query-should i use case?

  • Hi,

    I am not sure what the best approach is to accomplish what I need.Should I use case?

    1. If KEY in originalsheet is same as key in datasheet I need to add row same as original but values GrossAmount and TaxAmount must be in minus.

    2. If there are 2 colums with same code in original such as TaxOnNewOrder ( code 6) and NewOrder ( code 06)then take values from these 2 columns and place them in another row.

    3. If there is only one column with a code such as NewOrderDiv_Code ( code 37) -there is no other column with code 37 then add a new row with key 37 and no tax values and grossamount is what is under column NewOrderDiv_Code ( code 37)

    I added columns [TaxOnNewOrder_Code] and [NewOrderDiv_Code] for simplicity sakes in order to get the code-the tables are imported from EXCEL.

    CREATE TABLE [dbo].[DataSheet](

    [Acc No] [nvarchar](255) NULL,

    [nvarchar](255) NULL,

    [PayDate] [datetime] NULL,

    [nvarchar](255) NULL,

    [NewOrder_Code] [float] NULL,

    [NewOrder ( code 6)] [float] NULL,

    [TaxOnNewOrder_Code] [float] NULL,

    [TaxOnNewOrder ( code 06)] [float] NULL,

    [NewOrderDiv_Code ] [float] NULL,

    [NewOrderDiv_Code ( code 37)] [float] NULL

    ) ON [PRIMARY]

    GO

    insert into [DataSheet]

    select '0967889','06','2011-04-15 00:00:00.000','113011103',6,'324.15',6,'81.04',37,'83.53'

    union

    select '0967889','06','2011-04-15 00:00:00.000','009011109',6,'15.12',6,'81.04',37,'33.33'

    union

    select '0967889','06','2011-06-21 00:00:00.000','873061707',6,'324.15',6,'81.04',37,'83.53'

    union

    select '0967889','06','2011-12-25 00:00:00.000','893123403',6,'23.15',6,'80.00',37,'12.12'

    CREATE TABLE [dbo].[originalsheet](

    [AccountNo] [nvarchar](255) NULL,

    [nvarchar](255) NULL,

    [PayDate] [datetime] NULL,

    [nvarchar](255) NULL,

    [GrossAmount] [money] NULL,

    [TaxRate] [float] NULL,

    [TaxAmount] [money] NULL

    ) ON [PRIMARY]

    GO

    insert into [originalsheet]

    select '0967889','06','2011-04-15 00:00:00.000','113011103' ,'124.15' ,'25' ,'31.038'

    union

    select '0967889','06','2011-04-15 00:00:00.000','009011109' ,'622.96' ,'25' ,'155.74'

    union

    select '0967889','06','2011-06-21 00:00:00.000','873061707' ,'223' ,'25' ,'55.80'

    union

    select '0967889','06','2011-12-25 00:00:00.000','893123403' ,'407.68' ,'25' ,'101.92'

    output (black rows are from original table)

  • You can try the query below. If it produces the correct 3 records you need for each row, just add an INSERT before it to put them into the table.

    SELECT a.[Acc No], a., a.PayDate, a.[Code]

    ,TaxAmount=CASE WHEN Code1 IS NULL THEN -c.TaxAmount

    WHEN Code1 = Code2 THEN b.Order2

    ELSE 0 END

    ,[TaxRate]=CASE WHEN Code1 IS NULL THEN c.[TaxRate]

    WHEN Code1 = Code2 THEN c.[TaxRate]

    ELSE 0 END

    ,[GrossAmount]=CASE WHEN Code1 IS NULL THEN -c.[GrossAmount]

    WHEN Code1 = Code2 THEN b.Order1

    ELSE b.Order1 END

    FROM dbo.datasheet a

    CROSS APPLY (

    VALUES (NULL, NULL, NULL, NULL)

    ,(NewOrder_Code, [NewOrder ( code 6)], [TaxOnNewOrder_Code], [TaxOnNewOrder ( code 06)])

    ,([NewOrderDiv_Code ], [NewOrderDiv_Code ( code 37)], NULL, NULL)) b (Code1, [Order1], Code2, [Order2])

    INNER JOIN dbo.originalsheet c

    ON a.[Acc No] = c.[AccountNo] AND a. = c. AND a.PayDate = c.PayDate AND

    a.[Code] = c.[Code]


    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

  • BTW. Your DDL setup data was pretty good, except that I needed to fix it a little:

    jadelola (12/18/2012)


    CREATE TABLE [dbo].[DataSheet](

    [Acc No] [nvarchar](255) NULL,

    [nvarchar](255) NULL,

    [PayDate] [datetime] NULL,

    [nvarchar](255) NULL,

    [NewOrder_Code] [float] NULL,

    [NewOrder ( code 6)] [float] NULL,

    [TaxOnNewOrder_Code] [float] NULL,

    [TaxOnNewOrder ( code 06)] [float] NULL,

    [NewOrderDiv_Code ] [float] NULL,

    [NewOrderDiv_Code ( code 37)] [float] NULL

    ) ON [PRIMARY]

    ...

    CREATE TABLE [dbo].[originalsheet](

    [AccountNo] [nvarchar](255) NULL,

    [nvarchar](255) NULL,

    [PayDate] [datetime] NULL,

    [nvarchar](255) NULL,

    [GrossAmount] [money] NULL,

    [TaxRate] [float] NULL,

    [TaxAmount] [money] NULL

    ) ON [PRIMARY]

    For each column in bold that was missing I made that column name [Code].


    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

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

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