SQL Clone
SQLServerCentral is supported by Redgate
 
Log in  ::  Register  ::  Not logged in
 
 
 


what's the best way to get rows to columns for this?


what's the best way to get rows to columns for this?

Author
Message
foxr4
foxr4
SSC-Enthusiastic
SSC-Enthusiastic (138 reputation)SSC-Enthusiastic (138 reputation)SSC-Enthusiastic (138 reputation)SSC-Enthusiastic (138 reputation)SSC-Enthusiastic (138 reputation)SSC-Enthusiastic (138 reputation)SSC-Enthusiastic (138 reputation)SSC-Enthusiastic (138 reputation)

Group: General Forum Members
Points: 138 Visits: 81
create table temptest
(lid varchar(10), dat varchar(20))

insert into temptest (lid,dat) values ('11','first')
insert into temptest (lid,dat) values ('11','second')
insert into temptest (lid,dat) values ('11','third')

insert into temptest (lid,dat) values ('12','box')
insert into temptest (lid,dat) values ('12','circle')
insert into temptest (lid,dat) values ('12','trap')

insert into temptest (lid,dat) values ('14','star')
insert into temptest (lid,dat) values ('14','planet')


--I want the results to be
lid, dat1, dat2, dat3
11,first,second,third
12, box, circle, trap
14, star, planet, <blank>
drew.allen
drew.allen
SSC Guru
SSC Guru (50K reputation)SSC Guru (50K reputation)SSC Guru (50K reputation)SSC Guru (50K reputation)SSC Guru (50K reputation)SSC Guru (50K reputation)SSC Guru (50K reputation)SSC Guru (50K reputation)

Group: General Forum Members
Points: 50599 Visits: 14720
This will do most of what you ask. You don't have a field that supports a sort consistent with your expected output, so I've used the one that comes closest.

;
WITH CTE AS
(
SELECT *, ROW_NUMBER() OVER(PARTITION BY lid ORDER BY dat) AS rn
FROM #temptest
)

SELECT lid,
MAX(CASE WHEN rn = 1 THEN dat END) AS dat1,
MAX(CASE WHEN rn = 2 THEN dat END) AS dat2,
MAX(CASE WHEN rn = 3 THEN dat END) AS dat3
FROM CTE
GROUP BY lid


Drew

PS: I could add a CASE expression to force your data into the right order, but that is unlikely to transfer well to your real data.


J. Drew Allen
Business Intelligence Analyst
Philadelphia, PA
How to post data/code on a forum to get the best help.
How to Post Performance Problems
Make sure that you include code in the appropriate IFCode tags, e.g. [code=sql]<your code here>[/code]. You can find the IFCode tags under the INSERT options when you are writing a post.
Sean Lange
Sean Lange
SSC Guru
SSC Guru (206K reputation)SSC Guru (206K reputation)SSC Guru (206K reputation)SSC Guru (206K reputation)SSC Guru (206K reputation)SSC Guru (206K reputation)SSC Guru (206K reputation)SSC Guru (206K reputation)

Group: General Forum Members
Points: 206839 Visits: 19047
Or if you don't have a consistent number of elements you can see the link in my signature about dynamic cross tabs.

_______________________________________________________________

Need help? Help us help you.

Read the article at http://www.sqlservercentral.com/articles/Best+Practices/61537/ for best practices on asking questions.

Need to split a string? Try Jeff Modens splitter.

Cross Tabs and Pivots, Part 1 – Converting Rows to Columns
Cross Tabs and Pivots, Part 2 - Dynamic Cross Tabs
Understanding and Using APPLY (Part 1)
Understanding and Using APPLY (Part 2)
Sergiy
Sergiy
SSC Guru
SSC Guru (80K reputation)SSC Guru (80K reputation)SSC Guru (80K reputation)SSC Guru (80K reputation)SSC Guru (80K reputation)SSC Guru (80K reputation)SSC Guru (80K reputation)SSC Guru (80K reputation)

Group: General Forum Members
Points: 80815 Visits: 13542
How do you define which value goes into dat1, which one into dat2 and which one into dat3?
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