SQL Clone
SQLServerCentral is supported by Redgate
 
Log in  ::  Register  ::  Not logged in
 
 
 


xml field into its own table


xml field into its own table

Author
Message
joseph.devereaux
joseph.devereaux
SSC Rookie
SSC Rookie (45 reputation)SSC Rookie (45 reputation)SSC Rookie (45 reputation)SSC Rookie (45 reputation)SSC Rookie (45 reputation)SSC Rookie (45 reputation)SSC Rookie (45 reputation)SSC Rookie (45 reputation)

Group: General Forum Members
Points: 45 Visits: 72
I have never worked with xml in SQL Server. I in cramming mode : any help would be greatly appreciated.

I have a table with an xml column.

End Game : a job that will export the table's xml column into a new table each month. To me, its a complex xml doc and I don't even know what it all means yet. Below is all I have. I am starting with the contents of the xml field. If you can show me how to get collumn into a table, that would be great. If i figure it out, i will post it. I need each prop name, index name, field name as a column.

<?xml version="1.0" encoding="UTF-8"?>
<form>
<metadata>
<prop name="caseIdentifier"><value>C01</value></prop>
<prop name="caseId"><value>01</value></prop>
<prop name="formTypeIdentifier"><value>ARDI_Form</value></prop>
<prop name="formIdentifier"><value>0000000001</value></prop>
</metadata>
<field name="sar_lawPhone_number_first" type="String"><value/></field>
<field name="sar_fi_state" type="String"><value>pa</value></field>
<field name="sar_corrects_prior_report" type="Boolean"><value>false</value></field>
<field name="sar_susTotal" type="String"><value>3100</value></field>
<field name="sar_cntPhone_area" type="String"><value>518</value></field>
<field name="sar_lawPhone_area_first" type="String"><value/></field>
<field name="suspect_information_unavailable" type="String"><value>false</value></field>
<field name="sar_lawName_second" type="String"><value/></field>
<field name="sar_lawPhone_area_second" type="String"><value/></field>
<field name="sar_susDateTo" type="Date"><date format="yyyy-MM-dd HH:mm:ss"><value>2011-07-06 00:00:00</value></date></field>
<field name="sar_fi_city" type="String"><value>Buffalo</value></field>
<field name="sar_datePrepared" type="Date"><date format="yyyy-MM-dd HH:mm:ss"><value>2011-07-26 14:08:00</value></date></field>
<field name="sar_agency_name" type="String"><value/></field>
<field name="sar_multiple_branches" type="Boolean"><value>true</value></field>
<field name="sar_fi_ad" type="String"><value>change st.</value></field>
<field name="sar_lawPhone_number_second" type="String"><value/></field>
<field name="sar_violation_type_other" type="String"><value/></field>
<field name="sar_notified" type="Boolean"><value>false</value></field>
<field name="sar_cntPhone_number" type="String"><value>2300</value></field>
<field name="sar_contactFirstName" type="String"><value>NIFER</value></field>
<field name="sar_fi_zipcode" type="String"><value>17710</value></field>
<field name="sar_susAmtRecovery" type="String"><value/></field>
<field name="sar_impact" type="Boolean"><value>false</value></field>
<field name="sar_primaryFederalRegulator" type="String"><value>D</value></field>
<field name="sar_fi_name" type="String"><value>Some Store</value></field>
<field name="sar_inst" type="String"><value/></field>
<field name="sar_free_text_shown" type="String"><value>THIS IS A TEST</value></field>
<field name="sar_susAmtLoss" type="String"><value/></field>
<field name="sar_lawName_first" type="String"><value/></field>
<field name="sar_contactLastName" type="String"><value>BONNIER</value></field>
<field name="sar_fi_ein" type="String"><value>160428985</value></field>
<field name="sar_susDateFrom" type="Date"><date format="yyyy-MM-dd HH:mm:ss"><value>2011-07-06 00:00:00</value></date></field>
<field name="sar_bank" type="String"><value>true</value></field>
<field name="sar_occup" type="String"><value>Branch Manager</value></field>
<field name="sar_contactMiddleName" type="String"><value/></field>
<field index="1" name="sar_entZipcode_1" setName="suspect" type="String"><value>191115803</value></field>
<field index="1" name="sar_issuingAuthority_1" setName="suspect" type="String"><value>state_PA</value></field>
<field index="1" name="sar_entState_1" setName="suspect" type="String"><value>PA</value></field>
<field index="1" name="sar_identificationNumber_1" setName="suspect" type="String"><value>218196940</value></field>
<field index="1" name="sar_entOccupation_1" setName="suspect" type="String"><value>Blue Collar</value></field>
<field index="1" name="sar_entMiddleName_1" setName="suspect" type="String"><value/></field>
<field index="1" name="sar_dateOfTermination_1" setName="suspect" type="Date"/>
<field index="1" name="sar_entConfession_1" setName="suspect" type="String"><value/></field>
<field index="1" name="sar_entFirstName_1" setName="suspect" type="String"><value>MAGID</value></field>
<field index="1" name="sar_entLastName_1" setName="suspect" type="String"><value>HAMIDA</value></field>
<field index="1" name="sar_form_of_identification_1" setName="suspect" type="String"><value>A</value></field>
<field index="1" name="sar_entPhoneW_area_1" setName="suspect" type="String"><value/></field>
<field index="1" name="sar_entPhone_area_1" setName="suspect" type="String"><value>267</value></field>
<field index="1" name="sar_insiderRelationShipStatus_1" setName="suspect" type="String"><value/></field>
<field index="1" name="sar_entPhone_number_1" setName="suspect" type="String"><value>4440103</value></field>
<field index="1" name="sar_entCountry_1" setName="suspect" type="String"><value>US</value></field>
<field index="1" name="sar_entTIN_1" setName="suspect" type="String"><value>218196940</value></field>
<field index="1" name="sar_relationshipToFI_Other_text_1" setName="suspect" type="String"><value/></field>
<field index="1" name="sar_entSerial_1" setName="suspect" type="String"><value>1</value></field>
<field index="1" name="sar_insiderRelationShip_1" setName="suspect" type="Boolean"><value/></field>
<field index="1" name="sar_entPhoneW_number_1" setName="suspect" type="String"><value/></field>
<field index="1" name="sar_entAddress_1" setName="suspect" type="String"><value>6300 algon ave unit 2 </value></field>
<field index="1" name="sar_entCity_1" setName="suspect" type="String"><value>PHILADELPHIA</value></field>
<field index="1" name="sar_entDOB_1" setName="suspect" type="Date"/>
<field index="1" name="sar_relationshipToFI_Director_1" setName="suspect" type="String"><value>false</value></field>
<field index="1" name="sar_relationshipToFI_Borrower_1" setName="suspect" type="String"><value>false</value></field>
<field index="1" name="sar_relationshipToFI_Agent_1" setName="suspect" type="String"><value>false</value></field>
<field index="1" name="sar_relationshipToFI_Broker_1" setName="suspect" type="String"><value>false</value></field>
<field index="1" name="sar_form_of_identification_other_text_1" setName="suspect" type="String"><value/></field>
<field index="1" name="sar_relationshipToFI_Accountant_1" setName="suspect" type="String"><value>false</value></field>
<field index="1" name="sar_relationshipToFI_Appraiser_1" setName="suspect" type="String"><value>false</value></field>
<field index="1" name="sar_relationshipToFI_Shareholder_1" setName="suspect" type="String"><value>false</value></field>
<field index="1" name="sar_relationshipToFI_Attorney_1" setName="suspect" type="String"><value>false</value></field>
<field index="1" name="sar_relationshipToFI_Other_1" setName="suspect" type="String"><value>false</value></field>
<field index="1" name="sar_relationshipToFI_Customer_1" setName="suspect" type="String"><value>true</value></field>
<field index="1" name="sar_relationshipToFI_Officer_1" setName="suspect" type="String"><value>false</value></field>
<field index="1" name="sar_relationshipToFI_Employee_1" setName="suspect" type="String"><value>false</value></field>
<field index="1" name="sar_branch_state_1" setName="branch" type="String"><value>NJ</value></field>
<field index="1" name="sar_branch_city_1" setName="branch" type="String"><value>Troy</value></field>
<field index="1" name="sar_branch_zipcode_1" setName="branch" type="String"><value>12182</value></field>
<field index="1" name="sar_branch_date_closed_1" setName="branch" type="Date"/>
<field index="1" name="sar_branch_key_1" setName="branch" type="String"><value>115</value></field>
<field index="1" name="sar_branch_ad_1" setName="branch" type="String"><value>820 Second Ave</value></field>
<field index="1" name="institution_city_for_branch_1" setName="branch" type="String"><value>Buffalo</value></field>
<field index="1" name="institution_name_for_branch_1" setName="branch" type="String"><value>Some Store</value></field>
<field index="1" name="institution_ein_or_ssn_for_branch_1" setName="branch" type="String"><value>160428985</value></field>
<field index="1" name="sar_contact_area_code_1" setName="branch" type="String"><value>518</value></field>
<field index="1" name="institution_state_code_for_branch_1" setName="branch" type="String"><value>NJ</value></field>
<field index="1" name="institution_address_for_branch_1" setName="branch" type="String"><value>726 Exchange st.</value></field>
<field index="1" name="institution_regulator_for_branch_1" setName="branch" type="String"><value>D</value></field>
<field index="1" name="sar_contact_title_1" setName="branch" type="String"><value>Branch Manager</value></field>
<field index="1" name="institution_zip_code_for_branch_1" setName="branch" type="String"><value>14210</value></field>
<field index="1" name="sar_contact_first_name_1" setName="branch" type="String"><value>John</value></field>
<field index="1" name="sar_contact_last_name_1" setName="branch" type="String"><value>BONNIER</value></field>
<field index="1" name="sar_contact_middle_name_1" setName="branch" type="String"><value/></field>
<field index="1" name="sar_contact_phone_number_1" setName="branch" type="String"><value>2354600</value></field>
<field index="1" name="sar_contact_institution_or_agency_1" setName="branch" type="String"><value/></field>
<field index="2" name="sar_branch_state_2" setName="branch" type="String"><value>NJ</value></field>
<field index="2" name="sar_branch_city_2" setName="branch" type="String"><value>NEW TOWN</value></field>
<field index="2" name="sar_branch_zipcode_2" setName="branch" type="String"><value>14094</value></field>
<field index="2" name="sar_branch_date_closed_2" setName="branch" type="Date"/>
<field index="2" name="sar_branch_key_2" setName="branch" type="String"><value>9</value></field>
<field index="2" name="sar_branch_ad_2" setName="branch" type="String"><value>55 East Ave</value></field>
<field index="2" name="institution_city_for_branch_2" setName="branch" type="String"><value>NEW TOWN</value></field>
<field index="2" name="institution_name_for_branch_2" setName="branch" type="String"><value>Some Store</value></field>
<field index="2" name="institution_ein_or_ssn_for_branch_2" setName="branch" type="String"><value/></field>
<field index="2" name="sar_contact_area_code_2" setName="branch" type="String"><value>716</value></field>
<field index="2" name="institution_state_code_for_branch_2" setName="branch" type="String"><value>NJ</value></field>
<field index="2" name="institution_address_for_branch_2" setName="branch" type="String"><value/></field>
<field index="2" name="sar_contact_title_2" setName="branch" type="String"><value>Branch Manager</value></field>
<field index="2" name="institution_regulator_for_branch_2" setName="branch" type="String"><value/></field>
<field index="2" name="institution_zip_code_for_branch_2" setName="branch" type="String"><value>140950000</value></field>
<field index="2" name="sar_contact_first_name_2" setName="branch" type="String"><value>KIM</value></field>
<field index="2" name="sar_contact_last_name_2" setName="branch" type="String"><value>GLENA</value></field>
<field index="2" name="sar_contact_middle_name_2" setName="branch" type="String"><value/></field>
<field index="2" name="sar_contact_phone_number_2" setName="branch" type="String"><value>6257770</value></field>
<field index="2" name="sar_contact_institution_or_agency_2" setName="branch" type="String"><value/></field>
<field index="1" name="sar_closed_1" setName="account" type="Boolean"><value>false</value></field>
<field index="1" name="sar_account_1" setName="account" type="String"><value>5147148</value></field>
</form>
joseph.devereaux
joseph.devereaux
SSC Rookie
SSC Rookie (45 reputation)SSC Rookie (45 reputation)SSC Rookie (45 reputation)SSC Rookie (45 reputation)SSC Rookie (45 reputation)SSC Rookie (45 reputation)SSC Rookie (45 reputation)SSC Rookie (45 reputation)

Group: General Forum Members
Points: 45 Visits: 72
The field containing the xml code above is a text field. Not sure if that matters at this point.

CREATE TABLE [dbo].[ABC_forms](
[f_int_id] [numeric](9, 0) NOT NULL,
[e_int_id] [numeric](9, 0) NOT NULL,
[f_type_in_id] [numeric](9, 0) NOT NULL,
[form_xml] [text] NULL,
) ON [PRIMARY] TEXTIMAGE_ON [PRIMARY]

GO
Arthur Olcot
Arthur Olcot
Hall of Fame
Hall of Fame (3.6K reputation)Hall of Fame (3.6K reputation)Hall of Fame (3.6K reputation)Hall of Fame (3.6K reputation)Hall of Fame (3.6K reputation)Hall of Fame (3.6K reputation)Hall of Fame (3.6K reputation)Hall of Fame (3.6K reputation)

Group: General Forum Members
Points: 3580 Visits: 1779
Hi,
You can use the xml methods to shred the xml to a flat table but because the data is stored in a text column, this will need to be casted to xml first. See example query that shreds the xml to a flat table. I've used a CTE but you could do it other ways depending on your needs and environment. I've used the .nodes method to shred the xml and the .value method to extract the specific data:


WITH xCTE AS
(
SELECT f_int_id ,
e_int_id ,
f_type_in_id ,
CAST(form_xml AS XML) AS form_xml
FROM dbo.ABC_forms
)
select t.c.value('local-name(.)', 'varchar(100)') as 'NodeName',
t.c.value('@name', 'varchar(100)') as 'Name',
t.c.value('@index', 'int') as 'Index',
t.c.value('@setName', 'varchar(100)') as 'setName',
t.c.value('@type', 'varchar(100)') as 'Type',
t.c.value('(value/text())[1]', 'varchar(100)') as 'NodeValue'
FROM xCTE
CROSS APPLY form_xml.nodes('(/form/metadata/prop, /form/field)') t(c)


joseph.devereaux
joseph.devereaux
SSC Rookie
SSC Rookie (45 reputation)SSC Rookie (45 reputation)SSC Rookie (45 reputation)SSC Rookie (45 reputation)SSC Rookie (45 reputation)SSC Rookie (45 reputation)SSC Rookie (45 reputation)SSC Rookie (45 reputation)

Group: General Forum Members
Points: 45 Visits: 72
thank you! I will use that and start from there.
joseph.devereaux
joseph.devereaux
SSC Rookie
SSC Rookie (45 reputation)SSC Rookie (45 reputation)SSC Rookie (45 reputation)SSC Rookie (45 reputation)SSC Rookie (45 reputation)SSC Rookie (45 reputation)SSC Rookie (45 reputation)SSC Rookie (45 reputation)

Group: General Forum Members
Points: 45 Visits: 72
I have found that the number of fields in the xml field vary from 50 to over 300. I am creating dynamic sql to add the fields to a new_xml_table. Then using dynamic sql to create updates to the new fields for each existing record. I will post the results.
Go


Permissions

You can't post new topics.
You can't post topic replies.
You can't post new polls.
You can't post replies to polls.
You can't edit your own topics.
You can't delete your own topics.
You can't edit other topics.
You can't delete other topics.
You can't edit your own posts.
You can't edit other posts.
You can't delete your own posts.
You can't delete other posts.
You can't post events.
You can't edit your own events.
You can't edit other events.
You can't delete your own events.
You can't delete other events.
You can't send private messages.
You can't send emails.
You can read topics.
You can't vote in polls.
You can't upload attachments.
You can download attachments.
You can't post HTML code.
You can't edit HTML code.
You can't post IFCode.
You can't post JavaScript.
You can post emoticons.
You can't post or upload images.

Select a forum

































































































































































SQLServerCentral


Search