Created
October 14, 2019 16:24
-
-
Save davidsheardown/5e52498c34b695784a8af17abdd1ed3a to your computer and use it in GitHub Desktop.
Dynamic XML data into columns with MS-SQL
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
| select dense_rank() over(order by ID, I.N) as ID, | |
| F.N.value('(Text/text())[1]', 'varchar(max)') as Name, | |
| F.N.value('(Value/text())[1]', 'varchar(max)') as Value | |
| into #T | |
| from YourTable as T | |
| cross apply T.XMLCol.nodes('/Items/Item') as I(N) | |
| cross apply I.N.nodes('FormItem') as F(N) | |
| declare @SQL nvarchar(max) | |
| declare @Col nvarchar(max) | |
| select @Col = | |
| ( | |
| select distinct ','+quotename(Name) | |
| from #T | |
| for xml path(''), type | |
| ).value('substring(text()[1], 2)', 'nvarchar(max)') | |
| set @SQL = 'select '+@Col+' | |
| from #T | |
| pivot (max(Value) for Name in ('+@Col+')) as P' | |
| exec (@SQL) | |
| drop table #T |
Sign up for free
to join this conversation on GitHub.
Already have an account?
Sign in to comment