Please start any new threads on our new site at https://forums.sqlteam.com. We've got lots of great SQL Server experts to answer whatever question you can come up with.

 All Forums
 General SQL Server Forums
 New to SQL Server Programming
 How to create a crosstab or pivot query

Author  Topic 

jmersing
Yak Posting Veteran

57 Posts

Posted - 2011-08-18 : 10:43:06

I have the following statement and I'd like to transform it into a crosstab query. Nothing I try works, I'm trying to make the field called StartTime as my Column header, I only need one header, the rest can be rows.

Thanks

SELECT DISTINCT TOP (2000) dbo.QUEUE.NAME, LEFT(CONVERT(varchar, dbo.QUEUEHISTORYTIMESERIES.TIME, 108), 2) AS StartTime,
SUM(dbo.QUEUEHISTORYTIMESERIES.CALLVOLUME) AS Volume

FROM dbo.QUEUE INNER JOIN dbo.QUEUEHISTORYTIMESERIES ON dbo.QUEUE.ID = dbo.QUEUEHISTORYTIMESERIES.QUEUEID

WHERE (CONVERT(varchar, dbo.QUEUEHISTORYTIMESERIES.TIME, 110) = CONVERT(varchar, DATEADD(Day, - 1, GETDATE()), 110))

GROUP BY LEFT(CONVERT(varchar, dbo.QUEUEHISTORYTIMESERIES.TIME, 108), 2), dbo.QUEUE.NAME
ORDER BY dbo.QUEUE.NAME, StartTime

visakh16
Very Important crosS Applying yaK Herder

52326 Posts

Posted - 2011-08-18 : 10:59:06
can you show your expected output? on which column value you need to pivot?

------------------------------------------------------------------------------------------------------
SQL Server MVP
http://visakhm.blogspot.com/

Go to Top of Page

jmersing
Yak Posting Veteran

57 Posts

Posted - 2011-08-18 : 11:25:05
Sure, sorry about that I want to pivot the row named LEFT(CONVERT(varchar, dbo.QUEUEHISTORYTIMESERIES.TIME, 108), 2) AS StartTime

So the Name would be a row, start time would be a colum header it goes from 1-24
And I want to sum the volume as the aggregate

_______1 - 2 - 3 - 4 - 5 - 6 - 7 - 8 - 9
Queue1 50 60 12 3 123 225 31 222 355

Hard to draw, hopefully you get the idea
Go to Top of Page

visakh16
Very Important crosS Applying yaK Herder

52326 Posts

Posted - 2011-08-18 : 11:31:06
[code]
SELECT NAME,
MAX(CASE WHEN StartTime = 1 THEN Volume ELSE NULL END) AS [1],
MAX(CASE WHEN StartTime = 2 THEN Volume ELSE NULL END) AS [2],
MAX(CASE WHEN StartTime = 3 THEN Volume ELSE NULL END) AS [3],
MAX(CASE WHEN StartTime = 4 THEN Volume ELSE NULL END) AS [4],
...
MAX(CASE WHEN StartTime = 24 THEN Volume ELSE NULL END) AS [24]
FROM
(
SELECT DISTINCT TOP (2000) dbo.QUEUE.NAME, LEFT(CONVERT(varchar, dbo.QUEUEHISTORYTIMESERIES.TIME, 108), 2) AS StartTime,
SUM(dbo.QUEUEHISTORYTIMESERIES.CALLVOLUME) AS Volume

FROM dbo.QUEUE INNER JOIN dbo.QUEUEHISTORYTIMESERIES ON dbo.QUEUE.ID = dbo.QUEUEHISTORYTIMESERIES.QUEUEID

WHERE (CONVERT(varchar, dbo.QUEUEHISTORYTIMESERIES.TIME, 110) = CONVERT(varchar, DATEADD(Day, - 1, GETDATE()), 110))

GROUP BY LEFT(CONVERT(varchar, dbo.QUEUEHISTORYTIMESERIES.TIME, 108), 2), dbo.QUEUE.NAME
)t
GROUP BY NAME
[/code]

------------------------------------------------------------------------------------------------------
SQL Server MVP
http://visakhm.blogspot.com/

Go to Top of Page

jmersing
Yak Posting Veteran

57 Posts

Posted - 2011-08-18 : 13:16:15
Wow that takes a lot of code to do I thought it would be simpler, I thought maybe I could use Pivot. It seems to work though, thank you.
Go to Top of Page

visakh16
Very Important crosS Applying yaK Herder

52326 Posts

Posted - 2011-08-18 : 13:26:16
you can even use pivot. in that case it would be like


SELECT NAME,
[1],[2],[3],[4],...,[24]
FROM
(
SELECT DISTINCT TOP (2000) dbo.QUEUE.NAME, LEFT(CONVERT(varchar, dbo.QUEUEHISTORYTIMESERIES.TIME, 108), 2) AS StartTime,
SUM(dbo.QUEUEHISTORYTIMESERIES.CALLVOLUME) AS Volume

FROM dbo.QUEUE INNER JOIN dbo.QUEUEHISTORYTIMESERIES ON dbo.QUEUE.ID = dbo.QUEUEHISTORYTIMESERIES.QUEUEID

WHERE (CONVERT(varchar, dbo.QUEUEHISTORYTIMESERIES.TIME, 110) = CONVERT(varchar, DATEADD(Day, - 1, GETDATE()), 110))

GROUP BY LEFT(CONVERT(varchar, dbo.QUEUEHISTORYTIMESERIES.TIME, 108), 2), dbo.QUEUE.NAME
)t
PIVOT (MAX(Volume) FOR StartTime IN ([1],[2],[3],....[24]))p


------------------------------------------------------------------------------------------------------
SQL Server MVP
http://visakhm.blogspot.com/

Go to Top of Page

visakh16
Very Important crosS Applying yaK Herder

52326 Posts

Posted - 2011-08-18 : 13:27:17
one more thing, for using PIVOT you should be on SQL 2005 or above with a compatibility level of over 90

------------------------------------------------------------------------------------------------------
SQL Server MVP
http://visakhm.blogspot.com/

Go to Top of Page
   

- Advertisement -