Created
July 27, 2015 18:46
-
-
Save timgaunt/0aa674bd63a004e714aa to your computer and use it in GitHub Desktop.
Export Umbraco data in pivot/crosstab table
This file contains 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 @cols NVARCHAR(max), @ContentTypeId int | |
SET @ContentTypeId = 1074 | |
SELECT @cols = STUFF(( | |
SELECT DISTINCT TOP 100 PERCENT | |
'],[' | |
+ CONVERT(varchar, Name + ' (' + CONVERT(varchar, id) + ')', 255) | |
FROM | |
dbo.cmsPropertyType | |
WHERE | |
contentTypeId = @ContentTypeId | |
ORDER BY | |
'],[' | |
+ CONVERT(varchar, Name + ' (' + CONVERT(varchar, id) + ')', 255) | |
FOR XML PATH('') | |
), 1, 2, '') + ']' | |
--SELECT @cols | |
DECLARE @query NVARCHAR(max) | |
SET @query = N'SELECT Id, ' + @cols + ' | |
FROM | |
( | |
SELECT | |
CONVERT(varchar, t.Name + '' ('' + CONVERT(varchar, t.id) + '')'', 255) As [PropId], | |
contentNodeId As [Id], | |
ISNULL(dataNvarchar, ISNULL(CONVERT(varchar, dataDate), ISNULL(CONVERT(varchar, dataInt), dataNtext))) As [Value] | |
FROM | |
dbo.cmsPropertyType t LEFT JOIN dbo.cmsPropertyData d ON t.id = d.propertytypeid | |
WHERE | |
contentTypeId = ' + CONVERT(varchar, @ContentTypeId) + ' | |
) p | |
PIVOT | |
( | |
MAX(Value) | |
FOR PropId IN ( '+ @cols +' ) | |
) AS pvt | |
ORDER BY Id ASC' | |
--PRINT(@query) | |
EXECUTE(@query) |
This file contains 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 @cols NVARCHAR(max) | |
SELECT @cols = STUFF(( | |
SELECT DISTINCT TOP 100 PERCENT | |
'],[' | |
+ CONVERT(varchar, Name + ' (' + CONVERT(varchar, id) + ')', 255) | |
FROM | |
dbo.cmsPropertyType t | |
WHERE | |
t.contentTypeId IN (1031, 1032, 1033) | |
ORDER BY | |
'],[' | |
+ CONVERT(varchar, Name + ' (' + CONVERT(varchar, id) + ')', 255) | |
FOR XML PATH('') | |
), 1, 2, '') + ']' | |
--SELECT @cols | |
DECLARE @query NVARCHAR(max) | |
SET @query = N'SELECT Id, ' + @cols + ' | |
FROM | |
( | |
SELECT | |
CONVERT(varchar, t.Name + '' ('' + CONVERT(varchar, t.id) + '')'', 255) As [PropId], | |
contentNodeId As [Id], | |
ISNULL(dataNvarchar, ISNULL(CONVERT(varchar, dataDate), ISNULL(CONVERT(varchar, dataInt), dataNtext))) As [Value] | |
FROM | |
dbo.cmsPropertyType t LEFT JOIN dbo.cmsPropertyData d ON t.id = d.propertytypeid | |
WHERE | |
t.contentTypeId IN (1031, 1032, 1033) | |
) p | |
PIVOT | |
( | |
MAX(Value) | |
FOR PropId IN ( '+ @cols +' ) | |
) AS pvt | |
ORDER BY Id ASC' | |
--PRINT(@query) | |
EXECUTE(@query) |
Sign up for free
to join this conversation on GitHub.
Already have an account?
Sign in to comment