Pivot

  • 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.

  • 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[/url].

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

  • 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

Viewing 4 posts - 1 through 3 (of 3 total)

You must be logged in to reply to this topic. Login to reply