Require expected output ,in row

Analyst_SQL 3,576 Reputation points
2021-02-18T09:15:25.257+00:00

Below is data ,i want to convert Bweight into Row as display in image.

CREATE TABLE #item (ItemCode int,ItemName varchar(max))  
  
CREATE TABLE #DistpatchM(DID int,E_Date date)  
CREATE TABLE #Distpatch_BD(ID int,DID int,Itemcode int,DisQTY int,Bweight int)  
     
INSERT INTO #item VALUES(1001, 'A')  
INSERT INTO #item VALUES(1002, 'B')  
INSERT INTO #item VALUES(1003, 'C')  
INSERT INTO #item VALUES(1004, 'D')  
INSERT INTO #item VALUES(1005, 'E')  
INSERT INTO #item VALUES(1006, 'F')  
INSERT INTO #item VALUES(1007, 'G')  
    
  
  
  
INSERT INTO #DistpatchM values(111,'2019-05-28')  
INSERT INTO #DistpatchM values(112,'2018-05-29')  
               
INSERT INTO #Distpatch_BD values(1,1001,111,1 ,500)  
INSERT INTO #Distpatch_BD values(2,1002,111 ,1,600)  
INSERT INTO #Distpatch_BD values(3,1003,111 ,1,800)  
INSERT INTO #Distpatch_BD values(4,1006,112,1,900)  
INSERT INTO #Distpatch_BD values(5,1006,112,1,4500)  
INSERT INTO #Distpatch_BD values(6,1006,112,1,650)  
INSERT INTO #Distpatch_BD values(7,1006,112,1,900)  
INSERT INTO #Distpatch_BD values(8,1006,112,1,4500)  
INSERT INTO #Distpatch_BD values(9,1006,112,1,650)  
INSERT INTO #Distpatch_BD values(10,1006,112,1,900)  
INSERT INTO #Distpatch_BD values(11,1006,112,1,4500)  
INSERT INTO #Distpatch_BD values(12,1006,112,1,650)  
INSERT INTO #Distpatch_BD values(13,1006,112,1,4500)  
INSERT INTO #Distpatch_BD values(14,1006,112,1,650)  
INSERT INTO #Distpatch_BD values(14,1001,112,1,400)  

Select  #item.ItemName,#Distpatch_BD.DisQTY,#Distpatch_BD.Bweight  
From #Distpatch_BD inner join #item on #item.itemcode=#Distpatch_BD.itemcode  
where #Distpatch_BD.DID=112  

69395-image.png

SQL Server Reporting Services
SQL Server Reporting Services
A SQL Server technology that supports the creation, management, and delivery of both traditional, paper-oriented reports and interactive, web-based reports.
3,061 questions
Developer technologies Transact-SQL
SQL Server Other
{count} votes

Accepted answer
  1. EchoLiu-MSFT 14,621 Reputation points
    2021-02-23T03:37:49.247+00:00

    According to Viorel-1's suggestion, the modified code should be::

     CREATE TABLE #item (ItemCode int,ItemName varchar(max))  
     CREATE TABLE #DistpatchM(DID int,E_Date date)  
     CREATE TABLE #Distpatch_BD(ID int, Itemcode int, DID int, DisQTY int, Bweight int)   
      
      
      
     INSERT INTO #item VALUES(1001, 'A')   
     INSERT INTO #item VALUES(1002, 'B')  
     INSERT INTO #item VALUES(1003, 'C')  
     INSERT INTO #item VALUES(1004, 'D')  
     INSERT INTO #item VALUES(1005, 'E')  
     INSERT INTO #item VALUES(1006, 'F')  
     INSERT INTO #item VALUES(1007, 'G')  
      
     INSERT INTO #DistpatchM values(111,'2019-05-28')  
     INSERT INTO #DistpatchM values(112,'2018-05-29')  
                       
     INSERT INTO #Distpatch_BD values(1,1001,111,1 ,500)  
     INSERT INTO #Distpatch_BD values(2,1002,111 ,1,600)  
     INSERT INTO #Distpatch_BD values(3,1003,111 ,1,800)  
     INSERT INTO #Distpatch_BD values(4,1006,112,1,900)  
     INSERT INTO #Distpatch_BD values(5,1006,112,1,4500)  
     INSERT INTO #Distpatch_BD values(6,1006,112,1,650)  
     INSERT INTO #Distpatch_BD values(7,1006,112,1,900)  
     INSERT INTO #Distpatch_BD values(8,1006,112,1,4500)  
     INSERT INTO #Distpatch_BD values(9,1006,112,1,650)  
     INSERT INTO #Distpatch_BD values(10,1006,112,1,900)  
     INSERT INTO #Distpatch_BD values(11,1006,112,1,4500)  
     INSERT INTO #Distpatch_BD values(12,1006,112,1,650)  
     INSERT INTO #Distpatch_BD values(13,1006,112,1,4500)  
     INSERT INTO #Distpatch_BD values(14,1006,112,1,650)  
     INSERT INTO #Distpatch_BD values(14,1001,112,1,400)  
      
      
      
    ;with I as  
     (  
         select *  
         from #Distpatch_BD  
         where DID in (112)  
     ),  
     N as  
     (  
         select *, row_number() over (partition by itemcode order by ID) - 1 as n  
         from I  
     ),  
     P as  
     (  
         select *, cast(Bweight as varchar(max)) as BweightT, n % 10 + 1 as c, n / 10 + 1 as r  
         from N  
     ),  
     G as  
     (  
         select *,   
             isnull(lead(BweightT, 0) over (partition by itemcode order by ID), '') as [1],  
             isnull(lead(BweightT, 1) over (partition by itemcode order by ID), '') as [2],  
             isnull(lead(BweightT, 2) over (partition by itemcode order by ID), '') as [3],  
             isnull(lead(BweightT, 3) over (partition by itemcode order by ID), '') as [4],  
             isnull(lead(BweightT, 4) over (partition by itemcode order by ID), '') as [5],  
             isnull(lead(BweightT, 5) over (partition by itemcode order by ID), '') as [6],  
             isnull(lead(BweightT, 6) over (partition by itemcode order by ID), '') as [7],  
             isnull(lead(BweightT, 7) over (partition by itemcode order by ID), '') as [8],  
             isnull(lead(BweightT, 8) over (partition by itemcode order by ID), '') as [9],  
             isnull(lead(BweightT, 9) over (partition by itemcode order by ID), '') as [10]  
         from P  
     ),  
     R as  
     (  
         select *   
         from G   
         where c = 1  
     ),  
     F as  
     (  
         select   
             case r when 1 then t.ItemName else '' end as Item,   
             case r when 1 then cast((select count(*) from I where itemcode = R.itemcode) as varchar(max)) else '' end as QTY,  
             case when lead(R.itemcode) over (partition by R.itemcode order by r) is null   
                 then cast((select sum(Bweight) from I where itemcode = R.itemcode) as varchar(max)) else '' end as Total,  
             R.*  
         from R  
         inner join #item t on t.ItemCode = R.itemcode  
     ),  
     GT as  
     (  
         select   
             cast(count(*) as varchar(max)) as GrandTotalQTY,   
             cast(sum(I.Bweight) as varchar(max)) as GrandTotalBWeight  
         from I  
     ),  
     E as  
     (  
         select distinct itemcode  
         from I  
     ),  
     U as  
     (  
         select itemcode, Item, QTY, [1], [2], [3], [4], [5], [6], [7], [8], [9], [10], Total, 1 as ord1, 1 as ord2  
         from F  
         union all  
         select itemcode, '', '', '', '', '', '', '', '', '', '', '', '', '', 2, 1  
         from E  
         union all  
         select NULL, 'Grand Total', GrandTotalQTY, '', '', '', '', '', '', '', '', '', '', GrandTotalBWeight, 1, 2  
         from GT  
     )  
     select Item, QTY, [1], [2], [3], [4], [5], [6], [7], [8], [9], [10], Total  
     from U  
     order by ord2, itemcode, ord1  
      
    

    Output:
    70893-image.png


2 additional answers

Sort by: Most helpful
  1. Viorel 122.5K Reputation points
    2021-02-19T19:41:09.36+00:00

    Check a long unoptimised solution too:

    ;
    with I as
    (
        select *
        from #Distpatch_BD
        where itemcode in (112)
    ),
    N as
    (
        select *, row_number() over (partition by DID order by ID) - 1 as n
        from I
    ),
    P as
    (
        select *, cast(Bweight as varchar(max)) as BweightT, n % 10 + 1 as c, n / 10 + 1 as r
        from N
    ),
    G as
    (
        select *, 
            isnull(lead(BweightT, 0) over (partition by DID order by ID), '') as [1],
            isnull(lead(BweightT, 1) over (partition by DID order by ID), '') as [2],
            isnull(lead(BweightT, 2) over (partition by DID order by ID), '') as [3],
            isnull(lead(BweightT, 3) over (partition by DID order by ID), '') as [4],
            isnull(lead(BweightT, 4) over (partition by DID order by ID), '') as [5],
            isnull(lead(BweightT, 5) over (partition by DID order by ID), '') as [6],
            isnull(lead(BweightT, 6) over (partition by DID order by ID), '') as [7],
            isnull(lead(BweightT, 7) over (partition by DID order by ID), '') as [8],
            isnull(lead(BweightT, 8) over (partition by DID order by ID), '') as [9],
            isnull(lead(BweightT, 9) over (partition by DID order by ID), '') as [10]
        from P
    ),
    R as
    (
        select * 
        from G 
        where c = 1
    ),
    F as
    (
        select 
            case r when 1 then t.ItemName else '' end as Item, 
            case r when 1 then cast((select count(*) from I where DID = R.DID) as varchar(max)) else '' end as QTY,
            case when lead(DID) over (partition by DID order by r) is null 
                then cast((select sum(Bweight) from I where DID = R.DID) as varchar(max)) else '' end as Total,
            R.*
        from R
        inner join #item t on t.ItemCode = R.DID
    ),
    GT as
    (
        select 
            cast(count(*) as varchar(max)) as GrandTotalQTY, 
            cast(sum(I.Bweight) as varchar(max)) as GrandTotalBWeight
        from I
    ),
    E as
    (
        select distinct DID
        from I
    ),
    U as
    (
        select DID, Item, QTY, [1], [2], [3], [4], [5], [6], [7], [8], [9], [10], Total, 1 as ord1, 1 as ord2
        from F
        union all
        select DID, '', '', '', '', '', '', '', '', '', '', '', '', '', 2, 1
        from E
        union all
        select NULL, 'Grand Total', GrandTotalQTY, '', '', '', '', '', '', '', '', '', '', GrandTotalBWeight, 1, 2
        from GT
    )
    select Item, QTY, [1], [2], [3], [4], [5], [6], [7], [8], [9], [10], Total
    from U
    order by ord2, DID, ord1
    
    1 person found this answer helpful.

  2. EchoLiu-MSFT 14,621 Reputation points
    2021-02-19T06:29:39.747+00:00
    ;with cte
    as(Select  i.ItemName,d.DisQTY,d.Bweight
    From #Distpatch_BD d
    inner join #item i
    on i.itemcode=d.DID
    where d.Itemcode=112)
    ,cte2 as(select *,row_number() over(partition by ItemName order by ItemName) rr 
             from cte)
    ,cte3
    as(select 'B' Item,* from (select rr,Bweight from cte2 where ItemName='F') as t  
       pivot (max(Bweight) for rr in ([1],[2],[3],[4],[5],[6],[7],[8],[9],[10],[11])) as p
       union all
       select 'A' Item,*,null,null,null,null,null,null,null,null,null,null from (select rr,Bweight from cte2 where ItemName='A') as t  
       pivot (max(Bweight) for rr in ([1])) as p)
    
    select * from cte3 
    order by Item
    

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.