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


Querying XML data


Querying XML data

Author
Message
mviggers
mviggers
SSC Rookie
SSC Rookie (44 reputation)SSC Rookie (44 reputation)SSC Rookie (44 reputation)SSC Rookie (44 reputation)SSC Rookie (44 reputation)SSC Rookie (44 reputation)SSC Rookie (44 reputation)SSC Rookie (44 reputation)

Group: General Forum Members
Points: 44 Visits: 49
Hi

I hope someone is able to help me with following query:


--LOAD TEST XML TO SQL SERVER XML COLUMN
declare @xml table (xmldata xml)
insert @xml select
'<organization>
<department>
<person>
<personId>1</personId>
<name>John Doe</name>
<note>
<date>2014-03-01</date>
<text>Here is a sample text 1</text>
</note>
<note>
<date>2014-03-02</date>
<text>Here is a sample text 2</text>
</note>
</person>
<person>
<personId>2</personId>
<name>Jane Doe</name>
<note>
<date>2014-03-03</date>
<text>Here is a sampe text 3</text>
</note>
<note>
<date>2014-03-04</date>
<text>Here is a sampe text 4</text>
</note>
</person>
</department>
</organization>'

--SELECT PERSON OBJECTS TO TABLE
select person.x.value('(./personId)[1]','varchar(max)') as personId, person.x.value('(./name)[1]','varchar(max)') as name
from @xml e
cross apply e.xmldata.nodes('/organization/department/person') as person(x)

/*
Result
------------
personid name
1 John Doe
2 Jane Doe
*/

--SELECT NOTE OBJECTS TO TABLE
select note.x.value('(./date)[1]','varchar(max)') as notedate, note.x.value('(./text)[1]','varchar(max)') as notetext
from @xml e
cross apply e.xmldata.nodes('/organization/department/person/note') as note(x)

/*
Result
------------
notedate notetext
2014-03-01 Here is a sample text 1
2014-03-02 Here is a sample text 2
2014-03-03 Here is a sampe text 3
2014-03-04 Here is a sampe text 4
*/



All above is correct. However I need the personId from person object to be selected in the note result (to use as foreign key). Expected result from note query is:


/*
Result
------------
personId notedate notetext
1 2014-03-01 Here is a sample text 1
1 2014-03-02 Here is a sample text 2
2 2014-03-03 Here is a sampe text 3
2 2014-03-04 Here is a sampe text 4
*/



Any advice is appreciated :-)

/Mikkel
LutzM
LutzM
SSC-Forever
SSC-Forever (42K reputation)SSC-Forever (42K reputation)SSC-Forever (42K reputation)SSC-Forever (42K reputation)SSC-Forever (42K reputation)SSC-Forever (42K reputation)SSC-Forever (42K reputation)SSC-Forever (42K reputation)

Group: General Forum Members
Points: 42693 Visits: 13559
something like tihs?
select 
person.x.value('(./personId)[1]','varchar(max)') as personId,
person.x.value('(./name)[1]','varchar(max)') as name,
note.y.value('(./date)[1]','varchar(max)') as [date],
note.y.value('(./text)[1]','varchar(max)') as [text]
from @xml e
cross apply e.xmldata.nodes('organization/department/person') as person(x)
outer apply person.x.nodes('note') as note(y)





Lutz
A pessimist is an optimist with experience.

How to get fast answers to your question
How to post performance related questions
Links for Tally Table , Cross Tabs and Dynamic Cross Tabs , Delimited Split Function
mviggers
mviggers
SSC Rookie
SSC Rookie (44 reputation)SSC Rookie (44 reputation)SSC Rookie (44 reputation)SSC Rookie (44 reputation)SSC Rookie (44 reputation)SSC Rookie (44 reputation)SSC Rookie (44 reputation)SSC Rookie (44 reputation)

Group: General Forum Members
Points: 44 Visits: 49
LutzM: Thank you, works as expected. Appreciate your help :-)...

LutzM (5/3/2014)
something like tihs?
select 
person.x.value('(./personId)[1]','varchar(max)') as personId,
person.x.value('(./name)[1]','varchar(max)') as name,
note.y.value('(./date)[1]','varchar(max)') as [date],
note.y.value('(./text)[1]','varchar(max)') as [text]
from @xml e
cross apply e.xmldata.nodes('organization/department/person') as person(x)
outer apply person.x.nodes('note') as note(y)


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