|
|
|
We know that SQL Server does not have TRANSFORM function or similar functionality which you have in MS Access but here is the stored procedure to make your life easy. |
Click here to copy the following block | Use master go drop proc sp_CrossTab go CREATE PROC sp_CrossTab @table AS sysname, @onrows AS nvarchar(128), @onrowsalias AS sysname = NULL, @oncols AS nvarchar(128), @sumcol AS sysname = NULL AS DECLARE @sql AS varchar(8000), @NEWLINE AS char(1)
SET @NEWLINE = CHAR(10)
SET @sql = 'SELECT' + @NEWLINE + ' ' + @onrows + CASE WHEN @onrowsalias IS NOT NULL THEN ' AS ' + @onrowsalias ELSE '' END
CREATE TABLE #keys(keyvalue nvarchar(100) NOT NULL PRIMARY KEY)
DECLARE @keyssql AS varchar(1000) SET @keyssql = 'INSERT INTO #keys ' + 'SELECT DISTINCT CAST(' + @oncols + ' AS nvarchar(100)) ' + 'FROM ' + @table
EXEC (@keyssql)
DECLARE @key AS nvarchar(100) SELECT @key = MIN(keyvalue) FROM #keys
WHILE @key IS NOT NULL BEGIN SET @sql = @sql + ',' + @NEWLINE + ' SUM(CASE CAST(' + @oncols + ' AS nvarchar(100))' + @NEWLINE + ' WHEN N''' + @key + ''' THEN ' + CASE WHEN @sumcol IS NULL THEN '1' ELSE @sumcol END + @NEWLINE + ' ELSE 0' + @NEWLINE + ' END) AS [' + @key + ']'
SELECT @key = MIN(keyvalue) FROM #keys WHERE keyvalue > @key END SET @sql = @sql + @NEWLINE + 'FROM ' + @table + @NEWLINE + 'GROUP BY ' + @onrows + @NEWLINE + 'ORDER BY ' + @onrows
EXEC (@sql) GO
GO USE Northwind go EXEC master.dbo.sp_CrossTab @table = 'Northwind.dbo.Orders', @onrows = 'MONTH(OrderDate)', @onrowsalias = 'OrderMonth', @oncols = 'YEAR(OrderDate)'
Go USE Pubs go EXEC master.dbo.sp_CrossTab @table = 'Pubs.dbo.Sales', @onrows = 'stor_id', @oncols = 'YEAR(ord_date)', @sumcol = 'qty' |
|
|
|
Submitted By :
Nayan Patel
(Member Since : 5/26/2004 12:23:06 PM)
|
|
|
Job Description :
He is the moderator of this site and currently working as an independent consultant. He works with VB.net/ASP.net, SQL Server and other MS technologies. He is MCSD.net, MCDBA and MCSE. In his free time he likes to watch funny movies and doing oil painting. |
View all (893) submissions by this author
(Birth Date : 7/14/1981 ) |
|
|