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


Transform data into column


Transform data into column

Author
Message
mzsleo85
mzsleo85
SSC Rookie
SSC Rookie (30 reputation)SSC Rookie (30 reputation)SSC Rookie (30 reputation)SSC Rookie (30 reputation)SSC Rookie (30 reputation)SSC Rookie (30 reputation)SSC Rookie (30 reputation)SSC Rookie (30 reputation)

Group: General Forum Members
Points: 30 Visits: 9
Hi All,

May any one help me in query for the below scenerio :


I have data like this in the table :


IntRecpieID strName intMealtypeID Total
100 ‘A’ 1 20
101 'B' 2 30
100 'A' 3 40



Desired Output required:

IntRecpieID StrName 1 2 3

100 'A' 20 Null 40

101 'B' Null 30 Null

I would be very greatfull to you.

Thanks in Advance
Sean Lange
Sean Lange
SSC Guru
SSC Guru (63K reputation)SSC Guru (63K reputation)SSC Guru (63K reputation)SSC Guru (63K reputation)SSC Guru (63K reputation)SSC Guru (63K reputation)SSC Guru (63K reputation)SSC Guru (63K reputation)

Group: General Forum Members
Points: 63184 Visits: 17962
Hi and welcome to the forums. It is considered best practice to post ddl and sample data so that we can work directly on your problem. Since this is your very first post I created it for you this time so you can what I mean. You can read more about best practices by following the link in my signature.

Here is an example of what you should include in your future posts.


create table #Something
(
IntRecpieID int,
strName char(1),
intMealtypeID int,
Total int
)

insert #Something
select 100, 'A', 1, 20 union all
select 101, 'B', 2, 30 union all
select 100, 'A', 3, 40

drop table #Something




The challenge you are facing is best handled using a cross tab. This is very common and is pretty simple to deal with. There are two types of cross tabs, static and dynamic. Based on your sample data you might be able to use the static version.

Here is how you could do the static version.


select IntRecpieID, strName,
MAX(case when intMealtypeID = 1 then Total end) as Total1,
MAX(case when intMealtypeID = 2 then Total end) as Total2,
MAX(case when intMealtypeID = 3 then Total end) as Total3
from #Something
group by IntRecpieID, strName



You can read more about cross tabs by following the links in my signature. Hope this works for you.

_______________________________________________________________

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)
mzsleo85
mzsleo85
SSC Rookie
SSC Rookie (30 reputation)SSC Rookie (30 reputation)SSC Rookie (30 reputation)SSC Rookie (30 reputation)SSC Rookie (30 reputation)SSC Rookie (30 reputation)SSC Rookie (30 reputation)SSC Rookie (30 reputation)

Group: General Forum Members
Points: 30 Visits: 9
Thank You Sean for your nice suggestions and help.
The solution which you provided me is working to me. (Thanks a lot)

I ll keep in mind all the points that were mentioned by you in future.

Thanks
Sean Lange
Sean Lange
SSC Guru
SSC Guru (63K reputation)SSC Guru (63K reputation)SSC Guru (63K reputation)SSC Guru (63K reputation)SSC Guru (63K reputation)SSC Guru (63K reputation)SSC Guru (63K reputation)SSC Guru (63K reputation)

Group: General Forum Members
Points: 63184 Visits: 17962
mzsleo85 (1/8/2014)
Thank You Sean for your nice suggestions and help.
The solution which you provided me is working to me. (Thanks a lot)

I ll keep in mind all the points that were mentioned by you in future.

Thanks


Awesome! Glad that worked you and thanks for letting me know.

_______________________________________________________________

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)
rkaram
rkaram
SSC Eights!
SSC Eights! (944 reputation)SSC Eights! (944 reputation)SSC Eights! (944 reputation)SSC Eights! (944 reputation)SSC Eights! (944 reputation)SSC Eights! (944 reputation)SSC Eights! (944 reputation)SSC Eights! (944 reputation)

Group: General Forum Members
Points: 944 Visits: 242
WHY U DONT USE THE PIVOT/UNPIVOT STATEMENTS TO TRANSFORM COLUMN DATA INTO MANY COLUMNS??

rkaram
Sean Lange
Sean Lange
SSC Guru
SSC Guru (63K reputation)SSC Guru (63K reputation)SSC Guru (63K reputation)SSC Guru (63K reputation)SSC Guru (63K reputation)SSC Guru (63K reputation)SSC Guru (63K reputation)SSC Guru (63K reputation)

Group: General Forum Members
Points: 63184 Visits: 17962
rabih_karam (1/16/2014)
WHY U DONT USE THE PIVOT/UNPIVOT STATEMENTS TO TRANSFORM COLUMN DATA INTO MANY COLUMNS??


Posting in call caps is considered yelling. No need to yell, we are all friends around here.

The PIVOT statement would work for this also. However, it generally will not perform as well as a cross tab. Additionally, at least for me, they are a lot easier to read and understand.

Take a look at the articles referenced in my signature about cross tabs. As always, Jeff Moden does an amazing job demonstrating various methods for this type of thing along with performance tests.

_______________________________________________________________

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)
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