Please start any new threads on our new site at https://forums.sqlteam.com. We've got lots of great SQL Server experts to answer whatever question you can come up with.

 All Forums
 General SQL Server Forums
 New to SQL Server Programming
 XML value

Author  Topic 

imperimus
Starting Member

2 Posts

Posted - 2014-01-14 : 10:53:07
Hi all

I have a column that contains the following xml:

<obj xmlns:xsd="http://www.w3.org/2001/XMLSchema" xmlns:xsi="http://www.w3.org/2001/XMLSchema-instance" xmlns="urn:vim25" versionId="5.1" xsi:type="ArrayOfKeyAnyValue">
<KeyAnyValue xsi:type="KeyAnyValue">
<key>1</key>
<value xsi:type="xsd:string">naa.6019cbc1a09e175d370df5320b00803a</value>
</KeyAnyValue>
<KeyAnyValue xsi:type="KeyAnyValue">
<key>2</key>
<value xsi:type="xsd:string">6215</value>
</KeyAnyValue>
<KeyAnyValue xsi:type="KeyAnyValue">
<key>3</key>
<value xsi:type="xsd:string">1291898</value>
</KeyAnyValue>
</obj>


I wish to return each of the key values as a separate column. I have tried:



SELECT [table].[column1]
,CONVERT(xml, [table].[column1]).value('(/obj/KeyAnyValue[1]/value)[1]', 'nvarchar(max)') As KeyValue


This just returns NULL. Have I got the XML path right?

Sure something simple i am doing wrong and much appreciate any help.

Thanks

visakh16
Very Important crosS Applying yaK Herder

52326 Posts

Posted - 2014-01-15 : 08:35:17
do you mean this?

declare @x xml='<obj xmlns:xsd="http://www.w3.org/2001/XMLSchema" xmlns:xsi="http://www.w3.org/2001/XMLSchema-instance" xmlns="urn:vim25" versionId="5.1" xsi:type="ArrayOfKeyAnyValue">
<KeyAnyValue xsi:type="KeyAnyValue">
<key>1</key>
<value xsi:type="xsd:string">naa.6019cbc1a09e175d370df5320b00803a</value>
</KeyAnyValue>
<KeyAnyValue xsi:type="KeyAnyValue">
<key>2</key>
<value xsi:type="xsd:string">6215</value>
</KeyAnyValue>
<KeyAnyValue xsi:type="KeyAnyValue">
<key>3</key>
<value xsi:type="xsd:string">1291898</value>
</KeyAnyValue>
</obj>'
;WITH XMLNAMESPACES ('http://www.w3.org/2001/XMLSchema' AS xsd,'http://www.w3.org/2001/XMLSchema-instance' AS xsi,'ArrayOfKeyAnyValue' as type,'urn:vim25' as [default])
select *
from(
SELECT t.u.value('(./default:key)[1]','int') as [Key],
t.u.value('(./default:value)[1]','varchar(100)') as value
FROM @x.nodes('/default:obj/default:KeyAnyValue')t(u)
)t
pivot(max(value) for [key] IN ([1],[2],[3]))p


output
------------------------------------------------------------
1 2 3
------------------------------------------------------------
naa.6019cbc1a09e175d370df5320b00803a 6215 1291898



------------------------------------------------------------------------------------------------------
SQL Server MVP
http://visakhm.blogspot.com/
https://www.facebook.com/VmBlogs
Go to Top of Page

imperimus
Starting Member

2 Posts

Posted - 2014-01-15 : 11:03:58
quote:
Originally posted by visakh16

do you mean this?

declare @x xml='<obj xmlns:xsd="http://www.w3.org/2001/XMLSchema" xmlns:xsi="http://www.w3.org/2001/XMLSchema-instance" xmlns="urn:vim25" versionId="5.1" xsi:type="ArrayOfKeyAnyValue">
<KeyAnyValue xsi:type="KeyAnyValue">
<key>1</key>
<value xsi:type="xsd:string">naa.6019cbc1a09e175d370df5320b00803a</value>
</KeyAnyValue>
<KeyAnyValue xsi:type="KeyAnyValue">
<key>2</key>
<value xsi:type="xsd:string">6215</value>
</KeyAnyValue>
<KeyAnyValue xsi:type="KeyAnyValue">
<key>3</key>
<value xsi:type="xsd:string">1291898</value>
</KeyAnyValue>
</obj>'
;WITH XMLNAMESPACES ('http://www.w3.org/2001/XMLSchema' AS xsd,'http://www.w3.org/2001/XMLSchema-instance' AS xsi,'ArrayOfKeyAnyValue' as type,'urn:vim25' as [default])
select *
from(
SELECT t.u.value('(./default:key)[1]','int') as [Key],
t.u.value('(./default:value)[1]','varchar(100)') as value
FROM @x.nodes('/default:obj/default:KeyAnyValue')t(u)
)t
pivot(max(value) for [key] IN ([1],[2],[3]))p


output
------------------------------------------------------------
1 2 3
------------------------------------------------------------
naa.6019cbc1a09e175d370df5320b00803a 6215 1291898



------------------------------------------------------------------------------------------------------
SQL Server MVP
http://visakhm.blogspot.com/
https://www.facebook.com/VmBlogs






This is spot on thank you very much, easy when you know how
Go to Top of Page

visakh16
Very Important crosS Applying yaK Herder

52326 Posts

Posted - 2014-01-16 : 04:50:49
welcome

------------------------------------------------------------------------------------------------------
SQL Server MVP
http://visakhm.blogspot.com/
https://www.facebook.com/VmBlogs
Go to Top of Page
   

- Advertisement -