A dynamic pivot table means you do not need to define hard coded column names as a dynamic query will fetch the field values from a column and use them as the column names while pivoting the source table.
Sounds complicated?
It is!
Good thing there are some code examples below you can just steal and alter as you need.
The first example will just return as a SELECT, the second example will write the results to a global temp table called ##Result.
A use case for this might be a continuous requirement to pivot a table however the column name requirements keep changing as field values change.
Example 1: Return as SELECT
/*Mock Table*/ IF OBJECT_ID('tempdb.dbo.#Fruits', 'U') IS NOT NULL DROP TABLE #Fruits; CREATE TABLE #Fruits ( Fruit VARCHAR(255) ,Quantity INT ,DateOf DATETIME ); INSERT INTO #Fruits ( Fruit ,Quantity ,DateOf ) VALUES ('Apple', 10 ,GETDATE()) ,('Orange', 10 ,GETDATE()) ,('Banana', 10, GETDATE()) ,('Apple', 11, DATEADD(DAY, - 1, GETDATE())) ,('Orange', 11, DATEADD(DAY, - 1, GETDATE())) ,('Banana', 11, DATEADD(DAY, - 1, GETDATE())) ,('Apple', 12, DATEADD(DAY, - 2, GETDATE())) ,('Orange', 12, DATEADD(DAY, - 2, GETDATE())) ,('Banana', 12, DATEADD(DAY, - 2, GETDATE())) ,('Apple', 13, DATEADD(DAY, - 3, GETDATE())) ,('Orange', 13, DATEADD(DAY, - 3, GETDATE())) ,('Banana', 13, DATEADD(DAY, - 3, GETDATE())); /*Demo Mock table*/ SELECT * FROM #Fruits; /*Logic to dynamically pivot table*/ DECLARE @cols AS NVARCHAR(MAX) ,@query AS NVARCHAR(MAX); SELECT @cols = STUFF(( SELECT DISTINCT QUOTENAME(f.[Fruit]) + ', ' FROM #Fruits AS f FOR XML PATH('') ,TYPE ).value('.', 'NVARCHAR(MAX)'), 1, 1, ''); /*Add missing square bracket to start of string*/ SET @cols = '[' + @cols; /*Remove last comma from string*/ SET @cols = SUBSTRING(@cols, 1, (LEN(@cols) - 1)); SET @query = 'SELECT [DateOf], ' + @cols + ' FROM ( SELECT * FROM #Fruits ) x pivot ( min(Quantity) for [Fruit] in (' + @cols + ') ) p ORDER BY RIGHT([DateOf], 4) ASC ,LEFT(RIGHT([DateOf], 7), 2) ASC ,LEFT([DateOf], 2) ASC'; EXECUTE (@query); DROP TABLE #Fruits;
Example 2: Write output to a table
IF OBJECT_ID('tempdb.dbo.##Result', 'U') IS NOT NULL DROP TABLE ##Result; /*Mock Table*/ IF OBJECT_ID('tempdb.dbo.#Fruits', 'U') IS NOT NULL DROP TABLE #Fruits; CREATE TABLE #Fruits ( Fruit VARCHAR(255) ,Quantity INT ,DateOf DATETIME ); INSERT INTO #Fruits ( Fruit ,Quantity ,DateOf ) VALUES ('Apple', 10 ,GETDATE()) ,('Orange', 10 ,GETDATE()) ,('Banana', 10, GETDATE()) ,('Apple', 11, DATEADD(DAY, - 1, GETDATE())) ,('Orange', 11, DATEADD(DAY, - 1, GETDATE())) ,('Banana', 11, DATEADD(DAY, - 1, GETDATE())) ,('Apple', 12, DATEADD(DAY, - 2, GETDATE())) ,('Orange', 12, DATEADD(DAY, - 2, GETDATE())) ,('Banana', 12, DATEADD(DAY, - 2, GETDATE())) ,('Apple', 13, DATEADD(DAY, - 3, GETDATE())) ,('Orange', 13, DATEADD(DAY, - 3, GETDATE())) ,('Banana', 13, DATEADD(DAY, - 3, GETDATE())); /*Demo Mock table*/ SELECT * FROM #Fruits; /*Logic to dynamically pivot table*/ DECLARE @cols AS NVARCHAR(MAX) ,@query AS NVARCHAR(MAX); SELECT @cols = STUFF(( SELECT DISTINCT QUOTENAME(f.[Fruit]) + ', ' FROM #Fruits AS f FOR XML PATH('') ,TYPE ).value('.', 'NVARCHAR(MAX)'), 1, 1, ''); /*Add missing square bracket to start of string*/ SET @cols = '[' + @cols; /*Remove last comma from string*/ SET @cols = SUBSTRING(@cols, 1, (LEN(@cols) - 1)); SET @query = 'SELECT [DateOf], ' + @cols + ' INTO ##Result FROM ( SELECT * FROM #Fruits ) x pivot ( min(Quantity) for [Fruit] in (' + @cols + ') ) p ORDER BY RIGHT([DateOf], 4) ASC ,LEFT(RIGHT([DateOf], 7), 2) ASC ,LEFT([DateOf], 2) ASC'; EXECUTE (@query); SELECT * FROM ##Result; DROP TABLE ##Result; DROP TABLE #Fruits;