Click here to monitor SSC
SQLServerCentral is supported by Redgate
 
Log in  ::  Register  ::  Not logged in
 
 
 


Convert Rows into Columns


Convert Rows into Columns

Author
Message
mpdillon
mpdillon
SSC-Enthusiastic
SSC-Enthusiastic (154 reputation)SSC-Enthusiastic (154 reputation)SSC-Enthusiastic (154 reputation)SSC-Enthusiastic (154 reputation)SSC-Enthusiastic (154 reputation)SSC-Enthusiastic (154 reputation)SSC-Enthusiastic (154 reputation)SSC-Enthusiastic (154 reputation)

Group: General Forum Members
Points: 154 Visits: 383
Comments posted to this topic are about the item Convert Rows into Columns
kevriley
kevriley
SSCrazy
SSCrazy (2.8K reputation)SSCrazy (2.8K reputation)SSCrazy (2.8K reputation)SSCrazy (2.8K reputation)SSCrazy (2.8K reputation)SSCrazy (2.8K reputation)SSCrazy (2.8K reputation)SSCrazy (2.8K reputation)

Group: General Forum Members
Points: 2813 Visits: 2606
Nice.

A simpler (IMHO) way of determining the ROWID is to simply subtract the Remainder from the RowNumber, a technique used a lot in "Gaps and Islands" solutions.


select
max(case when remainder = 0 then LotNo else '' end),
max(case when remainder = 1 then LotNo else '' end),
max(case when remainder = 2 then LotNo else '' end)
from
(
select
LotNo
, ( row_number() over ( order by LotNo ) +2 ) % 3 as Remainder
, row_number() over ( order by LotNo ) - ( row_number() over ( order by LotNo ) +2 ) % 3 as ROWID
from
lotno
)a
group by ROWID


Steph Locke
Steph Locke
SSC Veteran
SSC Veteran (231 reputation)SSC Veteran (231 reputation)SSC Veteran (231 reputation)SSC Veteran (231 reputation)SSC Veteran (231 reputation)SSC Veteran (231 reputation)SSC Veteran (231 reputation)SSC Veteran (231 reputation)

Group: General Forum Members
Points: 231 Visits: 870
This seems really useful but the article formatting could do with a bit of improving - not many of codeblocks are correctly formatted
Clif.Johnson-989960
Clif.Johnson-989960
Forum Newbie
Forum Newbie (1 reputation)Forum Newbie (1 reputation)Forum Newbie (1 reputation)Forum Newbie (1 reputation)Forum Newbie (1 reputation)Forum Newbie (1 reputation)Forum Newbie (1 reputation)Forum Newbie (1 reputation)

Group: General Forum Members
Points: 1 Visits: 265
Here's a shorter version. Hope it helps.


SELECT [0] Col1,[1] Col2,[2] Col3
FROM (
SELECT LotNo
, ((ROW_NUMBER() OVER (ORDER BY LotNo)-1) % 3) col
, ((ROW_NUMBER() OVER (ORDER BY LotNo)-1) / 3) roww
FROM (VALUES('A'),('B'),('C'),('D'),('E'),('F'),('G'),('H'),('I'),('J'),('K'),('L'),('M'),('N'),('O'),('P'),('Q'),('R'),('S'),('T'),('U'),('V'),('W'),('X'),('Y'),('Z'))t(LotNo)
) x
PIVOT (MIN(LotNo) FOR col IN ([0],[1],[2])) p



(2008 required for VALUES)
germany000
germany000
Forum Newbie
Forum Newbie (2 reputation)Forum Newbie (2 reputation)Forum Newbie (2 reputation)Forum Newbie (2 reputation)Forum Newbie (2 reputation)Forum Newbie (2 reputation)Forum Newbie (2 reputation)Forum Newbie (2 reputation)

Group: General Forum Members
Points: 2 Visits: 6
Wouldn't it be easier to use PIVOT and UNPIVOT to transpose the columns?

http://technet.microsoft.com/en-us/library/ms177410(v=sql.105).aspx
Luis Cazares
Luis Cazares
SSChampion
SSChampion (10K reputation)SSChampion (10K reputation)SSChampion (10K reputation)SSChampion (10K reputation)SSChampion (10K reputation)SSChampion (10K reputation)SSChampion (10K reputation)SSChampion (10K reputation)

Group: General Forum Members
Points: 10400 Visits: 18513
I once had a similar requirement and the best option was to generate the columns in the reporting tool. That was on VFP and I'm not sure if it's possible to do it in every reporting tool available, but it would certainly be easier to maintain and understand (single column from recordset printed in several columns on the report).
However, if someone needs to do it in T-SQL, it's a good option, but certainly the CASE statement is not necessary.


WITH MstrTable AS(
SELECT LotNo
, ( ROW_NUMBER() OVER ( ORDER BY LotNo ) + 2 ) % 3 as Remainder
, ( ROW_NUMBER() OVER ( ORDER BY LotNo ) + 2 ) / 3 as RowID
FROM LotNo
)
SELECT
MAX ( CASE WHEN remainder = 0 THEN LotNo ELSE '' END ) as Col1
,MAX ( CASE WHEN remainder = 1 THEN LotNo ELSE '' END ) as Col2
,MAX ( CASE WHEN remainder = 2 THEN LotNo ELSE '' END ) as Col3
FROM mstrtable
GROUP BY ROWID;

--Second option just for fun, but shouldn't be better and might be worse.
WITH Groups AS(
SELECT LotNo
, NTILE( (SELECT COUNT(*) FROM LotNo) / 3 + 1) OVER(ORDER BY LotNo) as RowID
FROM LotNo
),
mstrtable AS(
SELECT LotNo,
RowID,
ROW_NUMBER() OVER( PARTITION BY RowID ORDER BY LotNo) AS remainder
FROM Groups
)
SELECT
MAX ( CASE WHEN remainder = 1 THEN LotNo ELSE '' END ) as Col1
,MAX ( CASE WHEN remainder = 2 THEN LotNo ELSE '' END ) as Col2
,MAX ( CASE WHEN remainder = 3 THEN LotNo ELSE '' END ) as Col3
FROM mstrtable
GROUP BY ROWID;




Luis C.
General Disclaimer:
Are you seriously taking the advice and code from someone from the internet without testing it? Do you at least understand it? Or can it easily kill your server?


How to post data/code on a forum to get the best help: Option 1 / Option 2
Robert.Sterbal
Robert.Sterbal
SSC Veteran
SSC Veteran (243 reputation)SSC Veteran (243 reputation)SSC Veteran (243 reputation)SSC Veteran (243 reputation)SSC Veteran (243 reputation)SSC Veteran (243 reputation)SSC Veteran (243 reputation)SSC Veteran (243 reputation)

Group: General Forum Members
Points: 243 Visits: 2000
Looks like a great technique, although more than half the sites I support are SQL Server 2K

I'll have to figure out how to do this in excel (with the so I can take a column and spread it into 3.

Thanks!
Luis Cazares
Luis Cazares
SSChampion
SSChampion (10K reputation)SSChampion (10K reputation)SSChampion (10K reputation)SSChampion (10K reputation)SSChampion (10K reputation)SSChampion (10K reputation)SSChampion (10K reputation)SSChampion (10K reputation)

Group: General Forum Members
Points: 10400 Visits: 18513
Robert.Sterbal (7/17/2014)
Looks like a great technique, although more than half the sites I support are SQL Server 2K

I'll have to figure out how to do this in excel (with the so I can take a column and spread it into 3.

Thanks!

Hey Robert,
For 2000, you could use a temp table with a new identity to ensure the gaps are not a problem.
Here's an example using the same data as the article.

SELECT IDENTITY( int, 3, 1) AS RowNo, --Note the Identity definition starts at 3
LotNo
INTO #LotNo
FROM LotNo

SELECT MAX( CASE WHEN RowNo % 3 = 0 THEN LotNo ELSE '' END) AS Column1,
MAX( CASE WHEN RowNo % 3 = 1 THEN LotNo ELSE '' END) AS Column2,
MAX( CASE WHEN RowNo % 3 = 2 THEN LotNo ELSE '' END) AS Column3
FROM #LotNo
GROUP BY RowNo / 3

DROP TABLE #LotNo




Luis C.
General Disclaimer:
Are you seriously taking the advice and code from someone from the internet without testing it? Do you at least understand it? Or can it easily kill your server?


How to post data/code on a forum to get the best help: Option 1 / Option 2
ScottPletcher
ScottPletcher
SSCarpal Tunnel
SSCarpal Tunnel (4.7K reputation)SSCarpal Tunnel (4.7K reputation)SSCarpal Tunnel (4.7K reputation)SSCarpal Tunnel (4.7K reputation)SSCarpal Tunnel (4.7K reputation)SSCarpal Tunnel (4.7K reputation)SSCarpal Tunnel (4.7K reputation)SSCarpal Tunnel (4.7K reputation)

Group: General Forum Members
Points: 4671 Visits: 6837
You really need only a single ROW_NUMBER function:


SELECT
MAX(CASE WHEN row_num % 3 = 0 THEN LotNo ELSE '' END) AS Lot1,
MAX(CASE WHEN row_num % 3 = 1 THEN LotNo ELSE '' END) AS Lot2,
MAX(CASE WHEN row_num % 3 = 2 THEN LotNo ELSE '' END) AS Lot3
FROM (
SELECT LotNo, ROW_NUMBER() OVER(ORDER BY LotNo) + 2 AS row_num
FROM LotNo
) AS derived
GROUP BY row_num / 3




SQL DBA,SQL Server MVP('07, '08, '09)

Prosecutor James Blackburn, in closing argument in the "Fatal Vision" murders trial: "If in the future, you should cry a tear, cry one for them [the murder victims]. If in the future, you should say a prayer, say one for them. And if in the future, you should light a candle, light one for them."
sgross 10581
sgross 10581
Forum Newbie
Forum Newbie (2 reputation)Forum Newbie (2 reputation)Forum Newbie (2 reputation)Forum Newbie (2 reputation)Forum Newbie (2 reputation)Forum Newbie (2 reputation)Forum Newbie (2 reputation)Forum Newbie (2 reputation)

Group: General Forum Members
Points: 2 Visits: 13
Is it possible to make this dynamic to discover the needed columns without Dynamic SQL?
Go


Permissions

You can't post new topics.
You can't post topic replies.
You can't post new polls.
You can't post replies to polls.
You can't edit your own topics.
You can't delete your own topics.
You can't edit other topics.
You can't delete other topics.
You can't edit your own posts.
You can't edit other posts.
You can't delete your own posts.
You can't delete other posts.
You can't post events.
You can't edit your own events.
You can't edit other events.
You can't delete your own events.
You can't delete other events.
You can't send private messages.
You can't send emails.
You can read topics.
You can't vote in polls.
You can't upload attachments.
You can download attachments.
You can't post HTML code.
You can't edit HTML code.
You can't post IFCode.
You can't post JavaScript.
You can post emoticons.
You can't post or upload images.

Select a forum

































































































































































SQLServerCentral


Search