Transpose/Pivot Help

  • Hi. I have a table & I need to transpose/pivot some of the columns into rows. The column that needs to be pivoted is related to another in that the Response column contains responses to the questions in the QuestionID column. I need to transpose/pivot the QuestionID column but keep the corresponding responses in their proper place. Below is an example that I did by hand. I searched the forum and there were several examples similar to what I'm looking for, but not quite close enough.

    Current format

    ClientIDDOV Form QuestionID Response

    7 3/1/2012Audit Alcohol1-001 0

    8 8/9/2011Audit Alcohol1-001 0

    8 1/11/2012Audit Alcohol1-001 0

    9 8/24/2011Audit Alcohol1-002 0

    9 2/18/2012Audit Alcohol1-002 1

    Desired format

    ClientIDDOV Form Alcohol1-001Alcohol1-002

    7 3/1/2012Audit 0

    8 8/9/2011Audit 0

    8 1/11/2012Audit 0

    9 8/24/2011Audit 0

    9 2/18/2012Audit 1

    Is there any way to do this? Any help would be greatly appreciated.

  • In the future, my suggestion is that you try to help your helpers a bit by providing DDL and consumable sample data like this:

    DECLARE @Imbibing TABLE

    (ClientID INT, DOV DATE, Form VARCHAR(10), QuestionID VARCHAR(20), Response INT)

    INSERT INTO @Imbibing

    SELECT 7, '3/1/2012','Audit','Alcohol1-001',0

    UNION ALL SELECT 8, '8/9/2011','Audit','Alcohol1-001',0

    UNION ALL SELECT 8, '1/11/2012','Audit','Alcohol1-001',0

    UNION ALL SELECT 9, '8/24/2011','Audit','Alcohol1-002',0

    UNION ALL SELECT 9, '2/18/2012','Audit','Alcohol1-002',1

    Remember that we're all volunteers here so this kindly helps us to respond quicker, better and with tested results.

    Now onto a proposed solution:

    SELECT ClientID, DOV, Form

    ,[Alcohol1-001]=CASE QuestionID WHEN 'Alcohol1-001' THEN 1 ELSE 0 END

    ,[Alcohol1-002]=CASE QuestionID WHEN 'Alcohol1-002' THEN 1 ELSE 0 END

    FROM @Imbibing

    Mind you this is only a guess, because in your "desired results" you show 5 column headers but only 4 data columns. And one of the Alcohol1-002 results rows doesn't match what I'm thinking you probably want.


    My mantra: No loops! No CURSORs! No RBAR! Hoo-uh![/I]

    My thought question: Have you ever been told that your query runs too fast?

    My advice:
    INDEXing a poor-performing query is like putting sugar on cat food. Yeah, it probably tastes better but are you sure you want to eat it?
    The path of least resistance can be a slippery slope. Take care that fixing your fixes of fixes doesn't snowball and end up costing you more than fixing the root cause would have in the first place.

    Need to UNPIVOT? Why not CROSS APPLY VALUES instead?[/url]
    Since random numbers are too important to be left to chance, let's generate some![/url]
    Learn to understand recursive CTEs by example.[/url]
    [url url=http://www.sqlservercentral.com/articles/St

  • Allow me to try again. The original file comes from an excel spreadsheet that I pull into SPSS & then export to a table in SQL. Then I wanted to write query to to pivot the necessary columns. Attached is the original data in excel & a spreadsheet with the 1st few cases pivoted.

  • ajames 36824 (2/20/2013)


    Allow me to try again. The original file comes from an excel spreadsheet that I pull into SPSS & then export to a table in SQL. Then I wanted to write query to to pivot the necessary columns. Attached is the original data in excel & a spreadsheet with the 1st few cases pivoted.

    I think you'll find many people (including myself) will be reluctant to open Excel spreadsheet attachments due to the potential for viruses.

    You should post consumable sample data as I did and your expected results (perhaps as an attached bitmap).


    My mantra: No loops! No CURSORs! No RBAR! Hoo-uh![/I]

    My thought question: Have you ever been told that your query runs too fast?

    My advice:
    INDEXing a poor-performing query is like putting sugar on cat food. Yeah, it probably tastes better but are you sure you want to eat it?
    The path of least resistance can be a slippery slope. Take care that fixing your fixes of fixes doesn't snowball and end up costing you more than fixing the root cause would have in the first place.

    Need to UNPIVOT? Why not CROSS APPLY VALUES instead?[/url]
    Since random numbers are too important to be left to chance, let's generate some![/url]
    Learn to understand recursive CTEs by example.[/url]
    [url url=http://www.sqlservercentral.com/articles/St

  • Okay, I did this both ways in the hopes that one would be correct. I have attached bitmap file & I created a query using the instructions in the "Forum Etiquette" to produce the data below

    SELECT "7","2012-03-01","Audit","Alcohol1-001","0" UNION ALL

    SELECT "7","2012-03-01","Audit","Alcohol1-001","0" UNION ALL

    SELECT "8","2011-08-09","Audit","Alcohol1-001","0" UNION ALL

    SELECT "8","2011-08-09","Audit","Alcohol2-002","0" UNION ALL

    SELECT "8","2012-01-11","Audit","Alcohol1-001","0" UNION ALL

    SELECT "8","2012-01-11","Audit","Alcohol2-002","0" UNION ALL

    SELECT "9","2011-08-24","Audit","Alcohol1-001","0" UNION ALL

    SELECT "9","2011-08-24","Audit","Alcohol2-002","0" UNION ALL

    SELECT "9","2012-02-18","Audit","Alcohol1-001","1" UNION ALL

    SELECT "9","2012-02-18","Audit","Alcohol2-002","0" UNION ALL

    SELECT "12","2012-02-14","Audit","Alcohol1-001","0" UNION ALL

    SELECT "12","2012-02-14","Audit","Alcohol2-002","0" UNION ALL

    SELECT "13","2011-09-28","Audit","Alcohol1-001","0" UNION ALL

    SELECT "43","2011-11-01","Audit","Alcohol1-001","0" UNION ALL

    SELECT "44","2011-11-21","Audit","Alcohol1-001","0" UNION ALL

    SELECT "157","2012-02-29","Audit","Alcohol1-001","0" UNION ALL

    SELECT "157","2012-06-20","Audit","Alcohol1-001","0" UNION ALL

    SELECT "158","2012-03-21","Audit","Alcohol1-001","0" UNION ALL

    SELECT "158","2012-07-11","Audit","Alcohol1-001","1" UNION ALL

    SELECT "160","2012-06-19","Audit","Alcohol1-001","0" UNION ALL

    SELECT "160","2012-11-09","Audit","Alcohol1-001","0" UNION ALL

    SELECT "164","2012-07-17","Audit","Alcohol1-001","0" UNION ALL

    SELECT "174","2012-06-06","Audit","Alcohol1-001","1" UNION ALL

    SELECT "178","2012-07-17","Audit","Alcohol1-001","0" UNION ALL

  • You're definitely on the right track to give us what we need to help you and reading the forum etiquette article was a smart thing to do.

    You didn't provide the DDL I asked for but I found that the DDL I used was good enough, so after changing the double quotes to single quotes and removing the last UNION ALL, this will run for me:

    DECLARE @Imbibing TABLE

    (ClientID INT, DOV DATE, Form VARCHAR(10), QuestionID VARCHAR(20), Response INT)

    INSERT INTO @Imbibing

    SELECT '7','2012-03-01','Audit','Alcohol1-001','0' UNION ALL

    SELECT '7','2012-03-01','Audit','Alcohol1-001','0' UNION ALL

    SELECT '8','2011-08-09','Audit','Alcohol1-001','0' UNION ALL

    SELECT '8','2011-08-09','Audit','Alcohol2-002','0' UNION ALL

    SELECT '8','2012-01-11','Audit','Alcohol1-001','0' UNION ALL

    SELECT '8','2012-01-11','Audit','Alcohol2-002','0' UNION ALL

    SELECT '9','2011-08-24','Audit','Alcohol1-001','0' UNION ALL

    SELECT '9','2011-08-24','Audit','Alcohol2-002','0' UNION ALL

    SELECT '9','2012-02-18','Audit','Alcohol1-001','1' UNION ALL

    SELECT '9','2012-02-18','Audit','Alcohol2-002','0' UNION ALL

    SELECT '12','2012-02-14','Audit','Alcohol1-001','0' UNION ALL

    SELECT '12','2012-02-14','Audit','Alcohol2-002','0' UNION ALL

    SELECT '13','2011-09-28','Audit','Alcohol1-001','0' UNION ALL

    SELECT '43','2011-11-01','Audit','Alcohol1-001','0' UNION ALL

    SELECT '44','2011-11-21','Audit','Alcohol1-001','0' UNION ALL

    SELECT '157','2012-02-29','Audit','Alcohol1-001','0' UNION ALL

    SELECT '157','2012-06-20','Audit','Alcohol1-001','0' UNION ALL

    SELECT '158','2012-03-21','Audit','Alcohol1-001','0' UNION ALL

    SELECT '158','2012-07-11','Audit','Alcohol1-001','1' UNION ALL

    SELECT '160','2012-06-19','Audit','Alcohol1-001','0' UNION ALL

    SELECT '160','2012-11-09','Audit','Alcohol1-001','0' UNION ALL

    SELECT '164','2012-07-17','Audit','Alcohol1-001','0' UNION ALL

    SELECT '174','2012-06-06','Audit','Alcohol1-001','1' UNION ALL

    SELECT '178','2012-07-17','Audit','Alcohol1-001','0'

    SELECT * FROM @Imbibing

    Now here is the issue. The BMP you provided shows the SELECT statements above that I've inserted into the temporary table. What it should show is the exact expected results based on the sample data you provided.


    My mantra: No loops! No CURSORs! No RBAR! Hoo-uh![/I]

    My thought question: Have you ever been told that your query runs too fast?

    My advice:
    INDEXing a poor-performing query is like putting sugar on cat food. Yeah, it probably tastes better but are you sure you want to eat it?
    The path of least resistance can be a slippery slope. Take care that fixing your fixes of fixes doesn't snowball and end up costing you more than fixing the root cause would have in the first place.

    Need to UNPIVOT? Why not CROSS APPLY VALUES instead?[/url]
    Since random numbers are too important to be left to chance, let's generate some![/url]
    Learn to understand recursive CTEs by example.[/url]
    [url url=http://www.sqlservercentral.com/articles/St

  • Thanks for cleaning that up. And that's right, you did say that bmp should be the desired results. Here you go.

  • Clarity is a beautiful thing.

    SELECT ClientID, DOV, Form

    ,[Alcohol1-001]=MAX(CASE QuestionID WHEN 'Alcohol1-001' THEN CAST(Response AS VARCHAR(3)) ELSE '' END )

    ,[Alcohol1-002]=MAX(CASE QuestionID WHEN 'Alcohol2-002' THEN CAST(Response AS VARCHAR(3)) ELSE '' END )

    FROM @Imbibing

    GROUP BY ClientID, DOV, Form


    My mantra: No loops! No CURSORs! No RBAR! Hoo-uh![/I]

    My thought question: Have you ever been told that your query runs too fast?

    My advice:
    INDEXing a poor-performing query is like putting sugar on cat food. Yeah, it probably tastes better but are you sure you want to eat it?
    The path of least resistance can be a slippery slope. Take care that fixing your fixes of fixes doesn't snowball and end up costing you more than fixing the root cause would have in the first place.

    Need to UNPIVOT? Why not CROSS APPLY VALUES instead?[/url]
    Since random numbers are too important to be left to chance, let's generate some![/url]
    Learn to understand recursive CTEs by example.[/url]
    [url url=http://www.sqlservercentral.com/articles/St

  • You ROCK! 😀

  • ajames 36824 (2/22/2013)


    You ROCK! 😀

    Do you understand how and why it works?

    --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 (2/22/2013)


    ajames 36824 (2/22/2013)


    You ROCK! 😀

    Do you understand how and why it works?

    Well it looks like it says that for each question in the QuestionID column, return the maximum numerical value related for the associated Response and making the rest blank. In order to do this, Response must be converted to characters. The Group By statement pivots all the other variables not in the statement and groups them based on those variables. Is that right?

  • ajames 36824 (2/22/2013)


    Jeff Moden (2/22/2013)


    ajames 36824 (2/22/2013)


    You ROCK! 😀

    Do you understand how and why it works?

    Well it looks like it says that for each question in the QuestionID column, return the maximum numerical value related for the associated Response and making the rest blank. In order to do this, Response must be converted to characters. The Group By statement pivots all the other variables not in the statement and groups them based on those variables. Is that right?

    Not sure I'd say it quite like that.

    The GROUP BY collapses all rows where the value of the grouped columns is the same, thus the rest of the columns are free to be pivoted. Which is done by one MAX/CASE per column to be pivoted.


    My mantra: No loops! No CURSORs! No RBAR! Hoo-uh![/I]

    My thought question: Have you ever been told that your query runs too fast?

    My advice:
    INDEXing a poor-performing query is like putting sugar on cat food. Yeah, it probably tastes better but are you sure you want to eat it?
    The path of least resistance can be a slippery slope. Take care that fixing your fixes of fixes doesn't snowball and end up costing you more than fixing the root cause would have in the first place.

    Need to UNPIVOT? Why not CROSS APPLY VALUES instead?[/url]
    Since random numbers are too important to be left to chance, let's generate some![/url]
    Learn to understand recursive CTEs by example.[/url]
    [url url=http://www.sqlservercentral.com/articles/St

  • ajames 36824 (2/22/2013)


    Jeff Moden (2/22/2013)


    ajames 36824 (2/22/2013)


    You ROCK! 😀

    Do you understand how and why it works?

    Well it looks like it says that for each question in the QuestionID column, return the maximum numerical value related for the associated Response and making the rest blank. In order to do this, Response must be converted to characters. The Group By statement pivots all the other variables not in the statement and groups them based on those variables. Is that right?

    Mostly correct. I say "mostly" because you don't actually need to convert the respose to VARCHAR. Dwaine did that just so he could show a blank instead of a NULL (which also suppresses the NULL aggregate warning messages).

    If you'd like to do a deeper dive on CrossTabs and Pivots, here are a couple of articles that start you on the ground floor and move you all the way through dynamic CrossTabs.

    http://www.sqlservercentral.com/articles/T-SQL/63681/

    http://www.sqlservercentral.com/articles/Crosstab/65048/

    --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 for the feedback & the articles.

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

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