Flip data in SQL

  • I have received data in the following format:

    ID, Name, [201401],[201402],[201403],[201404],[201405],[201406])

    '1', 'Joe', '0' , '0', '0', '0', '1', '0'

    '2' , 'Sam', '0' , '1', '0', '0', '0', '0'

    '3', 'Jill', '1' , '0', '0', '0', '0', '0'

    I want to flip data so that final result will be

    ID, Name, YrMnth Enrollment

    '1','Joe', 201401 '0'

    '1','Joe', 201402 '0'

    '1','Joe', 201403 '1'

    '1','Joe', 201404 '0'

    '1','Joe', 201405 '0'

    '1','Joe', 201406 '0'

    '1','Sam', 201401 '0'

    '1','Sam', 201402 '1'

    '1','Sam', 201403 '0'

    '1','Sam', 201404 '0'

    '1','Sam', 201405 '0'

    '1','Sam', 201406 '0'

    '1','Jill', 201401 '1'

    '1','Jill', 201402 '0'

    '1','Jill', 201403 '0'

    '1','Jill', 201404 '0'

    '1','Jill', 201405 '0'

    '1','Jill', 201406 '0'

    I did try to use Uni Pivot and sum(case) but with no avail. Any suggestions? her is SQL Codes for Test Data:

    IF OBJECT_ID('TempDB..#Table1') IS NOT NULL DROP TABLE #Table1

    --===== Create the test table with

    CREATE TABLE #Table1

    (

    ID INT,

    Name char(20) ,

    [201401] int,

    [201402] int,

    [201403] int,

    [201404] int,

    [201405] int,

    [201406] int

    )

    --===== Setup any special required conditions especially where dates are concerned

    --===== All Inserts into the IDENTITY column

    --===== Insert the test data into the test table

    INSERT INTO #Table1

    (ID, Name, [201401],[201402],[201403],[201404],[201405],[201406])

    SELECT '1','Joe','0' , '0', '0', '0', '1', '0' UNION ALL

    SELECT '2','Sam','1' , '0', '0', '0', '0', '0' UNION ALL

    SELECT '3','Jill','0' , '1', '0', '0', '0', '0'

    select *

    from #Table1

    Thank You,

    Helal

  • This does it and could be fairly easily converted to dynamic SQL if you needed it to be.

    SELECT t1.ID, t1.Name, ca.YrMnth, ca.Enrollment

    FROM #Table1 t1

    CROSS APPLY (

    SELECT '201401',[201401] UNION ALL

    SELECT '201402',[201402] UNION ALL

    SELECT '201403',[201403] UNION ALL

    SELECT '201404',[201404] UNION ALL

    SELECT '201405',[201405] UNION ALL

    SELECT '201406',[201406]

    ) ca (YrMnth,Enrollment)

    ;

    --Jeff Moden


    RBAR is pronounced "ree-bar" and is a "Modenism" for Row-By-Agonizing-Row.
    First step towards the paradigm shift of writing Set Based code:
    ________Stop thinking about what you want to do to a ROW... think, instead, of what you want to do to a COLUMN.

    Change is inevitable... Change for the better is not.


    Helpful Links:
    How to post code problems
    How to Post Performance Problems
    Create a Tally Function (fnTally)

  • Jeff,

    Thank you very much for your help. Just curious to know how to make it as dynamic SQL?

    Helal

  • This is how I would do it.

    For references:

    Creating the dynamic code[/url]

    Unpivoting the data[/url]

    DECLARE @SQL nvarchar(4000);

    SELECT @SQL = 'SELECT t1.ID, t1.Name, ca.YrMnth, ca.Enrollment

    FROM #Table1 t1

    CROSS APPLY ( '

    + STUFF(( SELECT ' UNION ALL

    SELECT ' + QUOTENAME( COLUMN_NAME, '''') + ', ' + QUOTENAME( COLUMN_NAME)

    FROM tempdb.INFORMATION_SCHEMA.COLUMNS

    WHERE TABLE_NAME LIKE '#Table1%'

    AND COLUMN_NAME NOT IN ('ID', 'Name')

    ORDER BY ORDINAL_POSITION

    FOR XML PATH(''),TYPE).value('.','varchar(MAX)'),1, 10, '')

    + ' ) ca (YrMnth,Enrollment);';

    PRINT @SQL;

    EXEC sp_executesql @SQL;

    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
  • helal.mobasher 13209 (3/1/2015)


    Jeff,

    Thank you very much for your help. Just curious to know how to make it as dynamic SQL?

    Helal

    Luis' code (above) will do the dynamic thing for you.

    --Jeff Moden


    RBAR is pronounced "ree-bar" and is a "Modenism" for Row-By-Agonizing-Row.
    First step towards the paradigm shift of writing Set Based code:
    ________Stop thinking about what you want to do to a ROW... think, instead, of what you want to do to a COLUMN.

    Change is inevitable... Change for the better is not.


    Helpful Links:
    How to post code problems
    How to Post Performance Problems
    Create a Tally Function (fnTally)

  • Thanks Luic for dynamic SQL. Very elaborate and I need to test it. However, on your note "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?" you made several assumptions. For one, how do you that I didn't test Jeff's codes? in fact I did for three years of data that add up to 60K records. Results were a snap. Second taking anything from Internet...well true that SQL Servercentral is internet source, but I thought only people with great skills or want to have better skills in SQL join SQL servercentral. And Do I even understand it? I am not as well versed as you and Jeff, but yes, I do understand it and did some incremental testing on Jeff's codes. Again, thank you for sharing your efficient solution with me and I appreciate that but I didn't appreciate your condescending comments.

    Helal

  • helal.mobasher 13209 (3/3/2015)


    Thanks Luic for dynamic SQL. Very elaborate and I need to test it. However, on your note "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?" you made several assumptions. For one, how do you that I didn't test Jeff's codes? in fact I did for three years of data that add up to 60K records. Results were a snap. Second taking anything from Internet...well true that SQL Servercentral is internet source, but I thought only people with great skills or want to have better skills in SQL join SQL servercentral. And Do I even understand it? I am not as well versed as you and Jeff, but yes, I do understand it and did some incremental testing on Jeff's codes. Again, thank you for sharing your efficient solution with me and I appreciate that but I didn't appreciate your condescending comments.

    Helal

    Understand that that's just his signature line. It's his reminder to everyone not to just take something from the internet and blindly use it. It's not directed at you in particular. It appears on all of his posts.

    --Jeff Moden


    RBAR is pronounced "ree-bar" and is a "Modenism" for Row-By-Agonizing-Row.
    First step towards the paradigm shift of writing Set Based code:
    ________Stop thinking about what you want to do to a ROW... think, instead, of what you want to do to a COLUMN.

    Change is inevitable... Change for the better is not.


    Helpful Links:
    How to post code problems
    How to Post Performance Problems
    Create a Tally Function (fnTally)

  • helal.mobasher 13209 (3/3/2015)


    Thanks Luic for dynamic SQL. Very elaborate and I need to test it. However, on your note "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?" you made several assumptions. For one, how do you that I didn't test Jeff's codes? in fact I did for three years of data that add up to 60K records. Results were a snap. Second taking anything from Internet...well true that SQL Servercentral is internet source, but I thought only people with great skills or want to have better skills in SQL join SQL servercentral. And Do I even understand it? I am not as well versed as you and Jeff, but yes, I do understand it and did some incremental testing on Jeff's codes. Again, thank you for sharing your efficient solution with me and I appreciate that but I didn't appreciate your condescending comments.

    Helal

    Thank you for your feedback. I really appreciate the fact that you read those question which are part of my signature as mentioned by Jeff.

    You wouldn't believe the amount of people that just copy the code and run it. Some of us try to give well tested solutions but some people just give terrible advice and some people trust that the person giving an advice is an expert.

    Thank you for taking care of your job and keep learning. 🙂

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

    Thank you for your kind words and am sorry that I overlooked the fact that they were part of your signature. Again, Jeff and your codes saved my life.

    Helal

  • Why did the UNPIVOT not work for you?

    Here is what I came up with:

    SELECT l.ID, l.Name, l.YrMnth, l.Enrollment

    FROM (SELECT ID, Name, [201401],[201402],[201403],[201404],[201405],[201406]

    FROM #Table1) p

    UNPIVOT (Enrollment FOR YrMnth IN ([201401],[201402],[201403],[201404],[201405],[201406])

    ) AS l

    -------------------------------------------------------------
    we travel not to escape life but for life not to escape us
    Don't fear failure, fear regret.

  • below86 (3/4/2015)


    Why did the UNPIVOT not work for you?

    Here is what I came up with:

    SELECT l.ID, l.Name, l.YrMnth, l.Enrollment

    FROM (SELECT ID, Name, [201401],[201402],[201403],[201404],[201405],[201406]

    FROM #Table1) p

    UNPIVOT (Enrollment FOR YrMnth IN ([201401],[201402],[201403],[201404],[201405],[201406])

    ) AS l

    That should definitely work. The only reason I avoid it is because I avoid its brother PIVOT.

    --Jeff Moden


    RBAR is pronounced "ree-bar" and is a "Modenism" for Row-By-Agonizing-Row.
    First step towards the paradigm shift of writing Set Based code:
    ________Stop thinking about what you want to do to a ROW... think, instead, of what you want to do to a COLUMN.

    Change is inevitable... Change for the better is not.


    Helpful Links:
    How to post code problems
    How to Post Performance Problems
    Create a Tally Function (fnTally)

  • Jeff Moden (3/4/2015)


    below86 (3/4/2015)


    Why did the UNPIVOT not work for you?

    Here is what I came up with:

    SELECT l.ID, l.Name, l.YrMnth, l.Enrollment

    FROM (SELECT ID, Name, [201401],[201402],[201403],[201404],[201405],[201406]

    FROM #Table1) p

    UNPIVOT (Enrollment FOR YrMnth IN ([201401],[201402],[201403],[201404],[201405],[201406])

    ) AS l

    That should definitely work. The only reason I avoid it is because I avoid its brother PIVOT.

    It worked for tha sample data provided, and I've been using it quit a bit lately, converting data from warehouse model to another. It seems to be working really fast with the data I've tested so far. It will be a slow migration of data so no one table will have to many rows at a time. Each field in the UNPIVOT needs to be the same data type, exactly, if one field is a CHAR(1) and the others were CHAR(3), it would give you an error. I either CAST or CONVERT the fields to be the same, or I have set up a few different statements for each data type. This is more for information for others, I'm sure Jeff already knows these things.:-)

    -------------------------------------------------------------
    we travel not to escape life but for life not to escape us
    Don't fear failure, fear regret.

  • Correct but I do have to thank you for taking the time to amplify your answer. Well done.

    --Jeff Moden


    RBAR is pronounced "ree-bar" and is a "Modenism" for Row-By-Agonizing-Row.
    First step towards the paradigm shift of writing Set Based code:
    ________Stop thinking about what you want to do to a ROW... think, instead, of what you want to do to a COLUMN.

    Change is inevitable... Change for the better is not.


    Helpful Links:
    How to post code problems
    How to Post Performance Problems
    Create a Tally Function (fnTally)

  • May be that was my problem...data type didn't match.

Viewing 14 posts - 1 through 13 (of 13 total)

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