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


Transform XML record to master and detail table


Transform XML record to master and detail table

Author
Message
jason123
jason123
SSC-Enthusiastic
SSC-Enthusiastic (125 reputation)SSC-Enthusiastic (125 reputation)SSC-Enthusiastic (125 reputation)SSC-Enthusiastic (125 reputation)SSC-Enthusiastic (125 reputation)SSC-Enthusiastic (125 reputation)SSC-Enthusiastic (125 reputation)SSC-Enthusiastic (125 reputation)

Group: General Forum Members
Points: 125 Visits: 67
Hi everyone,

I have xml record as below

<row id="VFAL.2312" xml:space="preserve">
<c1>DETAIL</c1>
<c2>VFAL.2312</c2>
<c2 m="2">272101-01</c2>
<c2 m="3">AIR DLG-DOUBTFUL LOAN VB>1Y</c2>
<c90>1</c90>
<c91>43_VFC.2__OFS_BROWSERTC</c91>
<c92>1208061131</c92>
<c93>43_VFC.2_OFS_BROWSERTC</c93>
<c94>KH0010001</c94>
<c95>1</c95>
</row>

I want to read these records and transform them to master table and detail table as below:

Master Table

@ID Description
---------------------------------------------
VFAL.2312 Detail

Detail Table

@ID Detail description
--------------------------------------------------------------
VFAL.2312 272101-01
VFAL.2312 AIR DLG-DOUBTFUL LOAN VB

Thank for your help
dwain.c
dwain.c
SSCoach
SSCoach (17K reputation)SSCoach (17K reputation)SSCoach (17K reputation)SSCoach (17K reputation)SSCoach (17K reputation)SSCoach (17K reputation)SSCoach (17K reputation)SSCoach (17K reputation)

Group: General Forum Members
Points: 17359 Visits: 6431
I find that these XML questions are never as easy as they first seem to be.


DECLARE @xml XML

SELECT @xml =
'<row id="VFAL.2312" xml:space="preserve">
<c1>DETAIL</c1>
<c2>VFAL.2312</c2>
<c2 m="2">272101-01</c2>
<c2 m="3">AIR DLG-DOUBTFUL LOAN VB>1Y</c2>
<c90>1</c90>
<c91>43_VFC.2__OFS_BROWSERTC</c91>
<c92>1208061131</c92>
<c93>43_VFC.2_OFS_BROWSERTC</c93>
<c94>KH0010001</c94>
<c95>1</c95>
</row>'

SELECT [@ID]=row.value('@id[1]', 'VARCHAR(10)')
,[Description]=row.value('(./c1)[1]', 'VARCHAR(10)')
FROM (SELECT @xml) a(x) CROSS APPLY x.nodes('row') b(row)

SELECT [@ID]=row.value('(./c2)[1]', 'VARCHAR(10)')
,[Detail Description]
FROM (SELECT @xml) a(x) CROSS APPLY x.nodes('row') b(row)
CROSS APPLY (
VALUES (row.value('(./c2)[2]', 'VARCHAR(10)'))
,(row.value('(./c2)[3]', 'VARCHAR(50)'))) c ([Detail Description])




Probably your actual XML contains additional elements that need to be taken into consideration or other bits of information to be shredded out. But perhaps the above will get you started.

If you've never seen CROSS APPLY VALUES before, take a look here: http://www.sqlservercentral.com/articles/CROSS+APPLY+VALUES+UNPIVOT/91234/

Edit: BTW. I am no expert on XML so if someone out there has a better way to handle this particular example, I (and my fish) are all ears. :-)


My mantra: No loops! No CURSORs! No RBAR! Hoo-uh!

My thought question: Have you ever been told that your query runs too fast?

My advice:
INDEXing a poor-performing query is like putting sugar on cat food. Yeah, it probably tastes better but are you sure you want to eat it?
The path of least resistance can be a slippery slope. Take care that fixing your fixes of fixes doesn't snowball and end up costing you more than fixing the root cause would have in the first place.


Need to UNPIVOT? Why not CROSS APPLY VALUES instead?
Since random numbers are too important to be left to chance, let's generate some!
Learn to understand recursive CTEs by example.
Splitting strings based on patterns can be fast!
My temporal SQL musings: Calendar Tables, an Easter SQL, Time Slots and Self-maintaining, Contiguous Effective Dates in Temporal Tables
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