Last active
December 26, 2015 20:19
-
-
Save ronmichael/7207528 to your computer and use it in GitHub Desktop.
A table-valued function that converts XML into a table. Thanks to http://stackoverflow.com/questions/2266132/how-can-i-get-a-list-of-element-names-from-an-xml-value-in-sql-server
This file contains hidden or bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
declare @x xml = '<data UniqueID="1" Name="Bob"/><data UniqueID="2" Name="Joan"/>' | |
select * from dbo.fnu_XML_ToTable(@x) |
This file contains hidden or bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
CREATE FUNCTION dbo.fnu_XML_ToTable(@x XML) | |
RETURNS TABLE | |
AS RETURN | |
with cte as ( | |
SELECT | |
1 AS lvl, | |
x.value('local-name(.)','NVARCHAR(MAX)') AS Name, | |
CAST(NULL AS NVARCHAR(MAX)) AS ParentName, | |
CAST(1 AS INT) AS ParentPosition, | |
CAST(N'Element' AS NVARCHAR(20)) AS NodeType, | |
x.value('local-name(.)','NVARCHAR(MAX)') AS FullPath, | |
x.value('local-name(.)','NVARCHAR(MAX)') | |
+ N'[' | |
+ CAST(ROW_NUMBER() OVER(ORDER BY (SELECT 1)) AS NVARCHAR) | |
+ N']' AS XPath, | |
ROW_NUMBER() OVER(ORDER BY (SELECT 1)) AS Position, | |
x.value('local-name(.)','NVARCHAR(MAX)') AS Tree, | |
x.value('text()[1]','NVARCHAR(MAX)') AS Value, | |
x.query('.') AS this, | |
x.query('*') AS t, | |
CAST(CAST(1 AS VARBINARY(4)) AS VARBINARY(MAX)) AS Sort, | |
CAST(1 AS INT) AS ID | |
FROM @x.nodes('/*') a(x) | |
UNION ALL | |
SELECT | |
p.lvl + 1 AS lvl, | |
c.value('local-name(.)','NVARCHAR(MAX)') AS Name, | |
CAST(p.Name AS NVARCHAR(MAX)) AS ParentName, | |
CAST(p.Position AS INT) AS ParentPosition, | |
CAST(N'Element' AS NVARCHAR(20)) AS NodeType, | |
CAST(p.FullPath + N'/' + c.value('local-name(.)','NVARCHAR(MAX)') AS NVARCHAR(MAX)) AS FullPath, | |
CAST(p.XPath + N'/'+ c.value('local-name(.)','NVARCHAR(MAX)')+ N'['+ CAST(ROW_NUMBER() OVER(PARTITION BY c.value('local-name(.)','NVARCHAR(MAX)') | |
ORDER BY (SELECT 1)) AS NVARCHAR)+ N']' AS NVARCHAR(MAX)) AS XPath, | |
ROW_NUMBER() OVER(PARTITION BY c.value('local-name(.)','NVARCHAR(MAX)') | |
ORDER BY (SELECT 1)) AS Position, | |
CAST( SPACE(2 * p.lvl - 1) + N'|' + REPLICATE(N'-', 1) + c.value('local-name(.)','NVARCHAR(MAX)') AS NVARCHAR(MAX)) AS Tree, | |
CAST( c.value('text()[1]','NVARCHAR(MAX)') AS NVARCHAR(MAX) ) AS Value, c.query('.') AS this, | |
c.query('*') AS t, | |
CAST(p.Sort + CAST( (lvl + 1) * 1024 + (ROW_NUMBER() OVER(ORDER BY (SELECT 1)) * 2) AS VARBINARY(4)) AS VARBINARY(MAX) ) AS Sort, | |
CAST((lvl + 1) * 1024 + (ROW_NUMBER() OVER(ORDER BY (SELECT 1)) * 2) AS INT) | |
FROM cte p | |
CROSS APPLY p.t.nodes('*') b(c)), cte2 AS ( | |
SELECT | |
lvl AS Depth, | |
Name AS NodeName, | |
ParentName, | |
ParentPosition, | |
NodeType, | |
FullPath, | |
XPath, | |
Position, | |
Tree AS TreeView, | |
Value, | |
this AS XMLData, | |
Sort, ID | |
FROM cte | |
UNION ALL | |
SELECT | |
p.lvl, | |
x.value('local-name(.)','NVARCHAR(MAX)'), | |
p.Name, | |
p.Position, | |
CAST(N'Attribute' AS NVARCHAR(20)), | |
p.FullPath + N'/@' + x.value('local-name(.)','NVARCHAR(MAX)'), | |
p.XPath + N'/@' + x.value('local-name(.)','NVARCHAR(MAX)'), | |
1, | |
SPACE(2 * p.lvl - 1) + N'|' + REPLICATE('-', 1) | |
+ N'@' + x.value('local-name(.)','NVARCHAR(MAX)'), | |
x.value('.','NVARCHAR(MAX)'), | |
NULL, | |
p.Sort, | |
p.ID + 1 | |
FROM cte p | |
CROSS APPLY this.nodes('/*/@*') a(x) | |
) | |
SELECT | |
ROW_NUMBER() OVER(ORDER BY Sort, ID) AS ID, | |
ParentName, ParentPosition,Depth, NodeName, Position, | |
NodeType, FullPath, XPath, TreeView, Value, XMLData | |
FROM cte2 |
Sign up for free
to join this conversation on GitHub.
Already have an account?
Sign in to comment