Simple pivot (Rows into Column)

kasim mohamed 581 Reputation points
2021-05-18T18:32:45.14+00:00

Hi,

I have a data like below

create table #table (_ID float, _Name varchar(20), _Code varchar(20));

insert into #table values (11111, 'ABC', 'I10')
insert into #table values (11111, 'XYZ', 'A78.5')
insert into #table values (11112, 'ABC', 'I11')
insert into #table values (11112, 'XYZ', 'B78.5')
insert into #table values (11113, 'ABC', 'I12')
insert into #table values (11113, 'XYZ', 'C78.5')

select * from #table;
drop table #table;

![97598-image.png]2
I need to bring the row values into column (simple pivot)
i expecting the result like below

create table #Result (_ID float, ABC varchar(20), XYZ varchar(20));
insert into #Result values (11111, 'I10', 'A78.5')
insert into #Result values (11112, 'I11', 'B78.5')
insert into #Result values (11113, 'I12', 'C78.5')
select * from #Result;
drop table #Result;

97605-image.png
Thanks

Developer technologies | Transact-SQL
SQL Server | Other
{count} votes

4 answers

Sort by: Most helpful
  1. Guoxiong 8,206 Reputation points
    2021-05-18T18:48:19.033+00:00

    Try this:

    SELECT ISNULL(abc._ID, xyz._ID) AS _ID,
           abc.ABC,
           xyz.XYZ
    FROM (
        SELECT _ID, _Code AS ABC
        FROM #table
        WHERE _Name = 'ABC'
    ) AS abc
    FULL JOIN (
        SELECT _ID, _Code AS XYZ
        FROM #table
        WHERE _Name = 'XYZ'
    ) AS xyz
    
    0 comments No comments

  2. Viorel 122.6K Reputation points
    2021-05-18T18:56:16.03+00:00

    This seems to work too:

    select p.* from #table
    pivot ( max(_Code) for _Name in ([ABC], [XYZ]) ) p
    
    0 comments No comments

  3. Erland Sommarskog 121.4K Reputation points MVP Volunteer Moderator
    2021-05-18T21:34:32.557+00:00

    Here is a solution that users standard SQL and avoids Microsoft proprietary PIVOT operator, which I don't find very useful. The pattern below is a little more verbose, but it is more straightforward and easier to extend.

    SELECT _ID, MIN(CASE _Name WHEN 'ABC' THEN _Code END) AS ABC,
                MIN(CASE _Name WHEN 'XYZ' THEN _Code END) AS XYZ
    FROM   #table 
    GROUP  BY _ID
    

    By the way, float is an odd choice for an ID column...

    0 comments No comments

  4. MelissaMa-MSFT 24,221 Reputation points
    2021-05-19T01:35:58.373+00:00

    Hi @kasim mohamed ,

    Thank you so much for posting here in Microsoft Q&A.

    You could refer other experts' answers.

    In case you have many columns in your table to pivot, you could refer below dynamic way:

     declare @sql nvarchar(max)  
          
     select @sql=STUFF(( SELECT distinct  ',['+_Name+']'  FROM #table FOR XML PATH('') ), 1, 1, '')  
      
     set @sql=N' select p.* from #table  
     pivot ( max(_Code) for _Name in ('+@sql+')) p'  
          
     EXECUTE sp_executesql  @sql  
    

    Output:

    _ID	ABC	XYZ  
    11111	I10	A78.5  
    11112	I11	B78.5  
    11113	I12	C78.5  
    

    Best regards,
    Melissa


    If the answer is helpful, please click "Accept Answer" and upvote it.
    Note: Please follow the steps in our documentation to enable e-mail notifications if you want to receive the related email notification for this thread.

    0 comments No comments

Your answer

Answers can be marked as Accepted Answers by the question author, which helps users to know the answer solved the author's problem.