Click here to monitor SSC
SQLServerCentral is supported by Redgate
 
Log in  ::  Register  ::  Not logged in
 
 
 


pivot / unpivot


pivot / unpivot

Author
Message
amitkumarmailid
amitkumarmailid
Forum Newbie
Forum Newbie (1 reputation)Forum Newbie (1 reputation)Forum Newbie (1 reputation)Forum Newbie (1 reputation)Forum Newbie (1 reputation)Forum Newbie (1 reputation)Forum Newbie (1 reputation)Forum Newbie (1 reputation)

Group: General Forum Members
Points: 1 Visits: 24
hi...pls help...
i have a table with data as :
emp_code paydate basic hra med splall ....
a001 31-01-14 10000 2000 100 1000
a002 31-01-14 20000 2000 100 1000
a003 31-01-14 15000 2000 100 1000
a004 31-01-14 10000 2000 100 1000
a005 31-01-14 10000 2000 100 1000
a006 31-01-14 10000 2000 100 1000
a001 31-12-13 10000 2000 100 1000
a002 31-12-13 20000 2000 100 1000
a003 31-12-13 15000 2000 100 1000
a004 31-12-13 10000 2000 100 1000
a005 31-12-13 10000 2000 100 1000
a006 31-12-13 10000 2000 100 1000
.
.
...............................................................
AND NOW I NEED OUTPUT IN GIVEN FORMAT :

31-01-14 31-12-13
BASIC 75000 75000
HRA 12000 12000
MED 600 600
SPLALL 6000 6000


NOTE : SUM OF BASIC OF ALL EMP IN A MONTH 31-01-14: 75000
ChrisM@Work
ChrisM@Work
SSCrazy Eights
SSCrazy Eights (9K reputation)SSCrazy Eights (9K reputation)SSCrazy Eights (9K reputation)SSCrazy Eights (9K reputation)SSCrazy Eights (9K reputation)SSCrazy Eights (9K reputation)SSCrazy Eights (9K reputation)SSCrazy Eights (9K reputation)

Group: General Forum Members
Points: 9005 Visits: 19028
Hi and welcome to ssc.
There's an article for newcomers which you may find useful; http://www.sqlservercentral.com/articles/Best+Practices/61537/
If you take a little time to prepare a sample data script, forum users will be encouraged to participate in your thread.


This time I’ve prepared your sample data for you;

-- Sample data setup
SET DATEFORMAT DMY
DROP TABLE #Sample
CREATE TABLE #Sample (emp_code VARCHAR(4), paydate DATE, [basic] INT, hra INT, med INT, splall INT)
INSERT INTO #Sample VALUES
('a001', '31-01-14', 10000, 2000, 100, 1000),
('a002', '31-01-14', 20000, 2000, 100, 1000),
('a003', '31-01-14', 15000, 2000, 100, 1000),
('a004', '31-01-14', 10000, 2000, 100, 1000),
('a005', '31-01-14', 10000, 2000, 100, 1000),
('a006', '31-01-14', 10000, 2000, 100, 1000),
('a001', '31-12-13', 10000, 2000, 100, 1000),
('a002', '31-12-13', 20000, 2000, 100, 1000),
('a003', '31-12-13', 15000, 2000, 100, 1000),
('a004', '31-12-13', 10000, 2000, 100, 1000),
('a005', '31-12-13', 10000, 2000, 100, 1000),
('a006', '31-12-13', 10000, 2000, 100, 1000)

SELECT * FROM #Sample; -- check everything is ok (Stare & Compare)



Here’s a solution which employs both CROSS APPLY VALUES (a handy unpivot alternative championed by Dwain Camps) and CROSSTAB (championed by MVP Jeff Moden);

-- Solution
SELECT
Category,
[31-01-14] = SUM(CASE WHEN paydate = '31-01-14' THEN Amount END),
[31-12-13] = SUM(CASE WHEN paydate = '31-12-13' THEN Amount END)
FROM #Sample
CROSS APPLY (
VALUES
('basic', [basic]),
('hra', hra),
('med', med),
('splall', splall)
) x (Category, Amount)
GROUP BY Category


Test it rigorously. If there are any issues, post back, extending your sample data set if necessary to help explain your findings.

“Write the query the simplest way. If through testing it becomes clear that the performance is inadequate, consider alternative query forms.” - Gail Shaw

For fast, accurate and documented assistance in answering your questions, please read this article.
Understanding and using APPLY, (I) and (II) Paul White
Hidden RBAR: Triangular Joins / The "Numbers" or "Tally" Table: What it is and how it replaces a loop Jeff Moden
Exploring Recursive CTEs by Example Dwain Camps
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