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
 SQL Server 2005 Forums
 Transact-SQL (2005)
 Collapse Multiple Rows into 1 Row ?

Author  Topic 

rwaldron
Posting Yak Master

131 Posts

Posted - 2011-12-05 : 10:41:38


Hi all, I have a table that can contain multiple rows for the same TicketID.eg: ticket ID 30...
Is there a way to collapse this record into one row?

Is there some sort of pivot command that I need ?
Thx in advanced
Ray..


I have this



ID Date text DDL Status Company

29 01/12/2011 R1222 Alarm Open MyCompany1
30 02/12/2011 1 Alarm1 Open MyCompany2
30 02/12/2011 R000033 NULL Open MyCompany2
30 02/12/2011 12 Alarm3 Open MyCompany2
30 02/12/2011 Result NULL Open MyCompany2




But I want to "collapse" TicketID 30 into 1 row like below


ID Date text1 text2 text3 text4 DDL1 DDl2 DDl3 DDl4 Status Company

29 01/12/2011 R1222 NULL NULL NULL Alarm NULL NULL NULL Open Company1
30 02/12/2011 1 R000033 12 Result Alarm1 NULL Alarm3 NULL Open Comapny2

nigelrivett
Master Smack Fu Yak Hacker

3385 Posts

Posted - 2011-12-05 : 10:53:28
;with t as
(
select *, seq = ROW_NUMBER() over (partition by id order by text) from tbl
)
select t1.id, t1.date, t1.text, t2.text, t3.text, t4.text, t1.ddl, t1.dd2, t1.dd3, t1.dd4, t1.status, t1.company
from
(select * from t where seq = 1) t1
left join
(select * from t where seq = 2) t2
on t1.id = t2.id
left join
(select * from t where seq = 3) t3
on t1.id = t3.id
left join
(select * from t where seq = 4) t4
on t1.id = t4.id


==========================================
Cursors are useful if you don't know sql.
SSIS can be used in a similar way.
Beer is not cold and it isn't fizzy.
Go to Top of Page

nigelrivett
Master Smack Fu Yak Hacker

3385 Posts

Posted - 2011-12-05 : 10:56:20
Actually there doesn't seem to be anything there to order by - text doesn't work. You might need to add something to the table if that order you gave is important.

==========================================
Cursors are useful if you don't know sql.
SSIS can be used in a similar way.
Beer is not cold and it isn't fizzy.
Go to Top of Page

visakh16
Very Important crosS Applying yaK Herder

52326 Posts

Posted - 2011-12-05 : 11:53:52
something like

SELECT ID,Date,
MAX(CASE WHEN Rn=1 THEN [text] END) AS text1,
MAX(CASE WHEN Rn=2 THEN [text] END) AS text2,
MAX(CASE WHEN Rn=3 THEN [text] END) AS text3,
MAX(CASE WHEN Rn=4 THEN [text] END) AS text4,
MAX(CASE WHEN Rn=1 THEN [DDL] END) AS DDL1,
MAX(CASE WHEN Rn=2 THEN [DDL] END) AS DDL2,
MAX(CASE WHEN Rn=3 THEN [DDL] END) AS DDL3,
MAX(CASE WHEN Rn=4 THEN [DDL] END) AS DDL4,
Status,Company
FROM
(
SELECT ROW_NUMBER() OVER (PARTITION BY ID,Date,Status,Company ORDER BY ID) AS Rn,*
FROM Table
)t
GROUP BY ID,Date,Status,Company


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

Go to Top of Page

visakh16
Very Important crosS Applying yaK Herder

52326 Posts

Posted - 2011-12-05 : 11:56:34
But as Nigel says the Order of retrieval of values is not guaranteed unless you've a unique valued column on basis of which you can order

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

Go to Top of Page

rwaldron
Posting Yak Master

131 Posts

Posted - 2011-12-06 : 06:08:01
Hiya guys and thx for replying..
The order returned IS important..

For

select t1.id, t1.date, t1.text, t2.text, t3.text, t4.text, t1.ddl, t2.ddl, t3.ddl, t4.ddl, t1.status, t1.company
from
(select * from t where seq = 1) t1
left join
(select * from t where seq = 2) t2
on t1.id = t2.id
left join
(select * from t where seq = 3) t3
on t1.id = t3.id
left join
(select * from t where seq = 4) t4
on t1.id = t4.id




I get the following result

ID Date text1 text2 text3 text4 DDL1 DDl2 DDl3 DDl4 Status Company

29 01/12/2011 R1222 NULL NULL NULL Alarm NULL NULL NULL Open Company1
30 02/12/2011 1 12 R000033 Result Alarm1 Alarm3 NULL NULL Open Comapny2



For ID 30 text2 should be R000033 text3 should be 12 DDL2 should be NULL DDL3 should be Alarm3

I tried adding another column with unique id and set as primary key but the order is still incorrect?

Any more help please
Go to Top of Page

visakh16
Very Important crosS Applying yaK Herder

52326 Posts

Posted - 2011-12-06 : 06:16:44
try this

SELECT ID,Date,
MAX(CASE WHEN Rn=1 THEN [text] END) AS text1,
MAX(CASE WHEN Rn=2 THEN [text] END) AS text2,
MAX(CASE WHEN Rn=3 THEN [text] END) AS text3,
MAX(CASE WHEN Rn=4 THEN [text] END) AS text4,
MAX(CASE WHEN Rn=1 THEN [DDL] END) AS DDL1,
MAX(CASE WHEN Rn=2 THEN [DDL] END) AS DDL2,
MAX(CASE WHEN Rn=3 THEN [DDL] END) AS DDL3,
MAX(CASE WHEN Rn=4 THEN [DDL] END) AS DDL4,
Status,Company
FROM
(
SELECT ROW_NUMBER() OVER (PARTITION BY ID,Date,Status,Company ORDER BY YourPKcol),*
FROM Table
)t
GROUP BY ID,Date,Status,Company



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

Go to Top of Page

rwaldron
Posting Yak Master

131 Posts

Posted - 2011-12-06 : 06:30:51
Hiya guys,
I just tried visakh16 suggested code and it looks like its working fine including the order of values returned !

Are you worried that the table doesn't have a unique Id ?
Go to Top of Page

visakh16
Very Important crosS Applying yaK Herder

52326 Posts

Posted - 2011-12-06 : 06:44:41
quote:
Originally posted by rwaldron

Hiya guys,
I just tried visakh16 suggested code and it looks like its working fine including the order of values returned !

Are you worried that the table doesn't have a unique Id ?


yep...having a unique id make sure we will get results returned in correct order

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

Go to Top of Page

rwaldron
Posting Yak Master

131 Posts

Posted - 2011-12-06 : 07:37:29
Ok, agreed ..

Thanks so much you guys for your help..

Greatly appretiated

Ray..
Go to Top of Page

visakh16
Very Important crosS Applying yaK Herder

52326 Posts

Posted - 2011-12-06 : 10:26:33
wc

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

Go to Top of Page
   

- Advertisement -