Click here to monitor SSC
SQLServerCentral is supported by Red Gate Software Ltd.
 
Log in  ::  Register  ::  Not logged in
 
 
 
        
Home       Members    Calendar    Who's On


Add to briefcase

Transform data into column Expand / Collapse
Author
Message
Posted Wednesday, January 8, 2014 9:30 AM
Forum Newbie

Forum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum Newbie

Group: General Forum Members
Last Login: Thursday, September 11, 2014 1:05 AM
Points: 2, Visits: 7
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

Post #1528955
Posted Wednesday, January 8, 2014 10:03 AM


SSChampion

SSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampion

Group: General Forum Members
Last Login: Yesterday @ 4:03 PM
Points: 12,928, Visits: 12,347
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 Moden's 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)
Post #1528971
Posted Wednesday, January 8, 2014 10:58 AM
Forum Newbie

Forum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum Newbie

Group: General Forum Members
Last Login: Thursday, September 11, 2014 1:05 AM
Points: 2, Visits: 7
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
Post #1529002
Posted Wednesday, January 8, 2014 11:47 AM


SSChampion

SSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampion

Group: General Forum Members
Last Login: Yesterday @ 4:03 PM
Points: 12,928, Visits: 12,347
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 Moden's 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)
Post #1529026
Posted Thursday, January 16, 2014 3:31 AM
SSC Veteran

SSC VeteranSSC VeteranSSC VeteranSSC VeteranSSC VeteranSSC VeteranSSC VeteranSSC Veteran

Group: General Forum Members
Last Login: Thursday, September 11, 2014 6:38 AM
Points: 242, Visits: 85
WHY U DONT USE THE PIVOT/UNPIVOT STATEMENTS TO TRANSFORM COLUMN DATA INTO MANY COLUMNS??
Post #1531474
Posted Thursday, January 16, 2014 7:25 AM


SSChampion

SSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampion

Group: General Forum Members
Last Login: Yesterday @ 4:03 PM
Points: 12,928, Visits: 12,347
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 Moden's 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)
Post #1531564
« Prev Topic | Next Topic »

Add to briefcase

Permissions Expand / Collapse