May 20, 2013 at 8:47 am
If i have at table with a xml column datatype and want to create sql view which displays certain values from within xml nodes of ALL the table records (not just one) what is the best way to do this? All the examples I've seen take simply the value of one xml column of one records a produce a reuslt but what if I wanted to query over all the records and produce SUMS, group bys, ETC. Is the only way for me to creatre a sproc and loop through every record, insert them into a temp table, and then do my selects/aggregations? Or is there a better more efficient way?
thanks for any advice!
nick
May 20, 2013 at 8:59 am
Hi,
If you look at the details of this post it may help you. If I understand what you want....
http://www.sqlservercentral.com/Forums/Topic1438775-3077-1.aspx
Thanks,
Simon
May 20, 2013 at 9:12 am
Or.... here's a really simple example but should get you going....
/* Set up a table variable to hold the XML*/
DECLARE @table TABLE
(
RiskXML XML
)
/* Insert some very simple XML */
INSERT INTO @table
SELECT '<RISK>
<ID>1</ID>
<VALUE>20</VALUE>
</RISK>'
UNION ALL SELECT '<RISK>
<ID>2</ID>
<VALUE>20</VALUE>
</RISK>'
UNION ALL SELECT '<RISK>
<ID>3</ID>
<VALUE>20</VALUE>
</RISK>'
/* Prove it's in there! */
SELECT * FROM @table
/* This is how we can flatten (shred) it */
SELECT
r.risk.value('(ID)[1]', 'int') AS ID,
r.risk.value('(VALUE)[1]', 'int') AS Value
FROM
@table t
CROSS APPLY t.RiskXML.nodes('RISK') r(risk)
/* Simple aggregations on it */
SELECT
COUNT(r.risk.value('(ID)[1]', 'int')) AS [Count],
SUM(r.risk.value('(VALUE)[1]', 'int')) AS [Sum]
FROM
@table t
CROSS APPLY t.RiskXML.nodes('RISK') r(risk)
May 20, 2013 at 1:27 pm
Thanks Simon! Much obliged. Think you gave me enough to get started.
May 21, 2013 at 2:08 am
Cool, glad it's helped. Post back if you have any problems.
Thanks,
Simon
Viewing 5 posts - 1 through 4 (of 4 total)
You must be logged in to reply to this topic. Login to reply