January 25, 2018 at 10:12 am
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>
January 25, 2018 at 10:35 am
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
January 25, 2018 at 10:54 am
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 http://www.sqlservercentral.com/articles/Tally+Table/72993/.
Cross Tabs and Pivots, Part 1 – Converting Rows to Columns - http://www.sqlservercentral.com/articles/T-SQL/63681/
Cross Tabs and Pivots, Part 2 - Dynamic Cross Tabs - http://www.sqlservercentral.com/articles/Crosstab/65048/
Understanding and Using APPLY (Part 1) - http://www.sqlservercentral.com/articles/APPLY/69953/
Understanding and Using APPLY (Part 2) - http://www.sqlservercentral.com/articles/APPLY/69954/
January 27, 2018 at 5:58 am
How do you define which value goes into dat1, which one into dat2 and which one into dat3?
_____________
Code for TallyGenerator
Viewing 4 posts - 1 through 3 (of 3 total)
You must be logged in to reply to this topic. Login to reply