Click here to monitor SSC
SQLServerCentral is supported by Redgate
 
Log in  ::  Register  ::  Not logged in
 
 
 


Adding New Elements to Existing XML Data


Adding New Elements to Existing XML Data

Author
Message
Karl Kieninger
Karl Kieninger
SSC Rookie
SSC Rookie (31 reputation)SSC Rookie (31 reputation)SSC Rookie (31 reputation)SSC Rookie (31 reputation)SSC Rookie (31 reputation)SSC Rookie (31 reputation)SSC Rookie (31 reputation)SSC Rookie (31 reputation)

Group: General Forum Members
Points: 31 Visits: 289
say I've got an XML column containing something like this:
<doc>
<heading>
<orderid>1</orderid>
</heading>
<line>
<lineid>1</lineid>
</line>
<line>
<lineid>2</lineid>
</line>
</doc>


Now I am going to change the scheme to require a new element and I need to update all existing records with a new element and default value.

If the element will be a child of heading
<heading>
<orderid>1</orderid>
<headinginfo>default</headinginfo>
</heading>

which can only appear once I can use "update modify insert" method which has been discussed here and elsewhere.

However if the new element is a child of a repeatable element such as line
<line>
<lineid>1</lineid>
<lineinfo>default</lineinfo>
</line>
<line>
<lineid>2</lineid>
<lineinfo>default</lineinfo>
</line>


That method cannot work since insert will fail if it finds multiple insert locations.[A substantial shortcoming IMO.]

In practice my XML is much more complicated so I could not reasonable shred and flatten to do the change and the reconstruct via SQL.

So doubting I'm the first there to run into this, I'm wondering if anyone has a method they have found to efficiently make such changes.

Brute force would be to pull the xml out of record method, apply a transform, externally, and then update it back in. Can we do better?

[Edit: Maybe using regex viable.]

Thanks in advance.
Arthur Olcot
Arthur Olcot
Hall of Fame
Hall of Fame (3K reputation)Hall of Fame (3K reputation)Hall of Fame (3K reputation)Hall of Fame (3K reputation)Hall of Fame (3K reputation)Hall of Fame (3K reputation)Hall of Fame (3K reputation)Hall of Fame (3K reputation)

Group: General Forum Members
Points: 3042 Visits: 1777
I would use an XQuery flwor expression in your scenario. Here is an example to remodel the xml that you have provided and add the extra nodes to the xml schema:


DECLARE @XML XML
SET @XML = '
<doc>
<heading>
<orderid>1</orderid>
</heading>
<line>
<lineid>1</lineid>
</line>
<line>
<lineid>2</lineid>
</line>
</doc>'


SELECT @XML.query('for $x in /doc
return
<doc>
<heading>
{$x/heading/*}
<headinginfo>default</headinginfo>
</heading>
{
for $y in /doc/line
return
<line>
{$y/*}
<lineinfo>default</lineinfo>
</line>
}
</doc>
')


Karl Kieninger
Karl Kieninger
SSC Rookie
SSC Rookie (31 reputation)SSC Rookie (31 reputation)SSC Rookie (31 reputation)SSC Rookie (31 reputation)SSC Rookie (31 reputation)SSC Rookie (31 reputation)SSC Rookie (31 reputation)SSC Rookie (31 reputation)

Group: General Forum Members
Points: 31 Visits: 289
arthurolcot (9/7/2012)
I would use an XQuery for expression in your scenario.


I love the solution for the simple example. Sadly the XML I've actually got is, i think, far to large and complex to sue this method.

Thanks.
Arthur Olcot
Arthur Olcot
Hall of Fame
Hall of Fame (3K reputation)Hall of Fame (3K reputation)Hall of Fame (3K reputation)Hall of Fame (3K reputation)Hall of Fame (3K reputation)Hall of Fame (3K reputation)Hall of Fame (3K reputation)Hall of Fame (3K reputation)

Group: General Forum Members
Points: 3042 Visits: 1777
ok, without seeing more of the actual xml it is hard for me to comment on that.

However, have you seen this thread:

http://www.sqlservercentral.com/Forums/Topic1311855-21-1.aspx#bm1312389

I came up with this for someone who had similar requirements to yourself, but this adds a new attribute into every node rather than an element. It could be adapted to add an element instead. If nothing else, it may give you some further ideas on how you could achieve your requirements.
Karl Kieninger
Karl Kieninger
SSC Rookie
SSC Rookie (31 reputation)SSC Rookie (31 reputation)SSC Rookie (31 reputation)SSC Rookie (31 reputation)SSC Rookie (31 reputation)SSC Rookie (31 reputation)SSC Rookie (31 reputation)SSC Rookie (31 reputation)

Group: General Forum Members
Points: 31 Visits: 289
arthurolcot (9/10/2012)
ok, without seeing more of the actual xml it is hard for me to comment on that.

Fair enough.


I did review that thread before posting here. It is what inspired the line in my OP, "In practice my XML is much more complicated so I could not reasonably shred and flatten to do the change and the reconstruct via SQL."

I'm considering a regex solution, I ran across a mention this moring of mdq.XmlTransform at http://beyondrelational.com/modules/2/blogs/111/posts/10204/sql-2008-r2-mds-easter-egg.aspx. Our servers are still running 2008, so that probably doesn't get em there. But I'll be finding out why we haven't upgraded.

Thanks!
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