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


Pivot


Pivot

Author
Message
anand.dhamane
anand.dhamane
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: 6
I have data in my table in following format.

EmpID Height Weight Attitude Build DateID
1 5.2 65 Cool Good 1
1 5.2 55 Cool Average 2

The above data is related to same employee.By dateid column we can distinguish the data.
I need to show these details in the following format.

DateID
1 2
Height 5.2 5.2
Weight 65 55
Attitude Cool Cool
Build Good Average

Please help me to achieve this.
Thanks in advance.
Luis Cazares
Luis Cazares
SSC-Forever
SSC-Forever (42K reputation)SSC-Forever (42K reputation)SSC-Forever (42K reputation)SSC-Forever (42K reputation)SSC-Forever (42K reputation)SSC-Forever (42K reputation)SSC-Forever (42K reputation)SSC-Forever (42K reputation)

Group: General Forum Members
Points: 42193 Visits: 19829
Hi, welcome to the forums. This should be made on the application layer, but here's an option. It first unpivots the data with this method: http://www.sqlservercentral.com/articles/CROSS+APPLY+VALUES+UNPIVOT/91234/
And then I used a CROSS TAB approach which you can read about here: http://www.sqlservercentral.com/articles/T-SQL/63681/
WITH SampleData(EmpID, Height, Weight, Attitude, Build, DateID) AS(
SELECT 1, 5.2, 65, 'Cool', 'Good', 1 UNION ALL
SELECT 1, 5.2, 55, 'Cool', 'Average', 2
)
SELECT Name,
MAX( CASE WHEN DateID = 1 THEN Value END) ,
MAX( CASE WHEN DateID = 2 THEN Value END)
FROM SampleData
CROSS APPLY (VALUES
(1,'DateID', CAST( DateID AS varchar(10))),
(2,'Height', CAST( Height AS varchar(10))),
(3,'Weight', CAST( Weight AS varchar(10))),
(4,'Attitude', Attitude),
(5,'Build', Build))x(RowOrder, Name, Value)
GROUP BY Name,RowOrder
ORDER BY RowOrder



With an uncertain quantity of DateID you might want to consider a dynamic approach.


Luis C.
General Disclaimer:
Are you seriously taking the advice and code from someone from the internet without testing it? Do you at least understand it? Or can it easily kill your server?


How to post data/code on a forum to get the best help: Option 1 / Option 2
Mitesh Oswal
Mitesh Oswal
Ten Centuries
Ten Centuries (1.2K reputation)Ten Centuries (1.2K reputation)Ten Centuries (1.2K reputation)Ten Centuries (1.2K reputation)Ten Centuries (1.2K reputation)Ten Centuries (1.2K reputation)Ten Centuries (1.2K reputation)Ten Centuries (1.2K reputation)

Group: General Forum Members
Points: 1174 Visits: 653
Try to use dynamic pivot, this may help you,

DROP TABLE #t1
CREATE TABLE #t1
(
EmpID INT,
[Height] NVARCHAR(100),
[Weight] NVARCHAR(100),
[Attitude] NVARCHAR(100),
[Build] NVARCHAR(100),
[DateID] INT
)

INSERT INTO #t1
VALUES(1, '5.2', '65', 'Cool', 'Good', 1),(1, '5.2', '55', 'Cool', 'Average', 2),(1, '5.2', '55', 'Cool', 'Average', 3)

DECLARE @SQL NVARCHAR(MAX),@MinID INT,@MaxID INT,@DateID NVARCHAR(100)

SELECT @MinID = 2,@MaxID = MAX([DateID])
FROM #t1


SELECT @SQL = '(select * from #t1 E where [DateID] = 1 )E UNPIVOT ([1] FOR OrderName IN (Height, Weight, Attitude, Build))E1'

WHILE(@MinID<=@MaxID)
BEGIN


SELECT @SQL = @SQL +' INNER JOIN '
+'(select * from #t1 E where [DateID] = '+CAST(@MinID AS NVARCHAR(100))+' )E
UNPIVOT (['+CAST(@MinID AS NVARCHAR(100))+'] FOR OrderName IN (Height, Weight, Attitude, Build))E'+CAST(@MinID AS NVARCHAR(100))+
+' ON E1.EmpID = E'+CAST(@MinID AS NVARCHAR(100))+'.EmpID AND E1.OrderName = E'+CAST(@MinID AS NVARCHAR(100))+'.OrderName'

SELECT @MinID = @MinID + 1
END

SELECT @SQL = 'SELECT * FROM '+@SQL

EXEC(@SQL)








Regards,
Mitesh OSwal
+918698619998
Luis Cazares
Luis Cazares
SSC-Forever
SSC-Forever (42K reputation)SSC-Forever (42K reputation)SSC-Forever (42K reputation)SSC-Forever (42K reputation)SSC-Forever (42K reputation)SSC-Forever (42K reputation)SSC-Forever (42K reputation)SSC-Forever (42K reputation)

Group: General Forum Members
Points: 42193 Visits: 19829
One table scan per each DateID? That seems quite expensive.
Here's my dynamic approach based on my initial query and your sample data. ;-)



SET @SQL = ''
SELECT @SQL = @SQL + ',MAX( CASE WHEN DateID = ' + CAST( DateID AS varchar(10)) + ' THEN Value END) AS Date' + CAST( DateID AS varchar(10)) + CHAR(10)
FROM (SELECT DISTINCT DateID FROM #t1) t1

SET @SQL = 'SELECT Name ' + CHAR(10) + @SQL + CHAR(10) +
'FROM #t1
CROSS APPLY (VALUES
(1,''DateID'', CAST( DateID AS varchar(10))),
(2,''Height'', CAST( Height AS varchar(10))),
(3,''Weight'', CAST( Weight AS varchar(10))),
(4,''Attitude'', Attitude),
(5,''Build'', Build))x(RowOrder, Name, Value)
GROUP BY Name,RowOrder
ORDER BY RowOrder'

EXEC(@SQL)


No loops and the table is read once for the list of DateIds and once for the actual query.
You can find all details for this method on the link provided in my previous post. ;-)


Luis C.
General Disclaimer:
Are you seriously taking the advice and code from someone from the internet without testing it? Do you at least understand it? Or can it easily kill your server?


How to post data/code on a forum to get the best help: Option 1 / Option 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