Click here to Skip to main content
15,904,416 members
Please Sign up or sign in to vote.
0.00/5 (No votes)
See more:
XML
<USAGE>
 <Customer>ABC</Customer>
 <Age>38</Age>
 <Mobile>
   <Model>Nokia</Model>
   <Price>100</Price>
  </Mobile>
 <Mobile>
   <Model>Samsung</Model>
   <Price>300</Price>
  </Mobile>
</USAGE>



Need the output in this format
Customer  Age  Mobile    Price
ABC       38    Nokia     100
ABC       38    Samsung   300


I am passing the xml to xml variable.


SQL
SELECT 
					[xmlTable].[Customer].value('/Customer', 'varchar(100)') AS '[Customer]',
					[xmlTable].[Age].value('/Age','varchar(100)') AS '[Age]',
					(SELECT 
							[CustTable].Model.value('.','varchar(100)') AS 'Model'
						FROM @tallyXML.nodes('Mobile/Model') AS [CustTable](Model)),
					(SELECT 
							[CustTable].Price.value('.','varchar(100)') AS 'Price'
						FROM @tallyXML.nodes('Mobile/Price') AS [CustTable](Price))
			FROM @tallyXML.nodes('USAGE') AS [xmlTable])



Please guide me how can I get the result in desired format. There is another way sp_xml_preparedocument but I am not aware how to get the same format in that also.

Thanks
Posted

1 solution

Have a try with something like the following example:
SQL
declare @tallyXML as xml

set @tallyXML = '<USAGE>
 <Customer>ABC</Customer>
 <Age>38</Age>
 <Mobile>
   <Model>Nokia</Model>
   <Price>100</Price>
  </Mobile>
 <Mobile>
   <Model>Samsung</Model>
   <Price>300</Price>
  </Mobile>
</USAGE>'

SELECT CustTable.Mobile.value('../Customer[1]','varchar(100)') AS 'Customer',
       CustTable.Mobile.value('../Age[1]','varchar(100)') AS 'Age',
		CustTable.Mobile.value('./Model[1]','varchar(100)') AS 'Model',
		CustTable.Mobile.value('./Price[1]','varchar(100)') AS 'Price'
FROM @tallyXML.nodes('USAGE/Mobile')  as CustTable(Mobile)
 
Share this answer
 

This content, along with any associated source code and files, is licensed under The Code Project Open License (CPOL)



CodeProject, 20 Bay Street, 11th Floor Toronto, Ontario, Canada M5J 2N8 +1 (416) 849-8900