column update based on calculation and group by

  • Hi,

    I need to update the Perc column in Table_A

    This is based on the following calculation:

    ((Pass/VM_Id) * 100)

    and this needs to be grouped by DeliveryDate Where SummaryType > 0

    NOTES:

    In this example (where Id = 1), the Perc value should be updated to '0' (as the SummaryType = 0)

    The calculation needs to be rounded to 0 decimal places

    I also have to accommodate any divide by 0 issues

    USE [dbName]

    GO

    SET DATEFORMAT YMD

    /****** Object: Table [dbo].[Table_2] Script Date: 04/25/2013 10:34:51 ******/

    SET ANSI_NULLS ON

    GO

    SET QUOTED_IDENTIFIER ON

    GO

    CREATE TABLE [dbo].[Table_A](

    [Id] [int] IDENTITY(1,1) NOT NULL,

    DeliveryDate [SMALLDATETIME] NOT NULL,

    Pass [INT] NOT NULL,

    VM_Id [SMALLINT] NOT NULL,

    Perc [INT] NOT NULL,

    SummaryType[TINYINT] NOT NULL

    ) ON [PRIMARY]

    ;

    INSERT INTO Table_A

    (DeliveryDate, Pass, VM_Id, Perc, SummaryType)

    VALUES ('2013-04-17', 1, 1, '0', '0')

    ;

    INSERT INTO Table_A

    (DeliveryDate, Pass, VM_Id, Perc, SummaryType)

    VALUES ('2013-04-24', 1, 1, '0', '1')

    ;

    INSERT INTO Table_A

    (DeliveryDate, Pass, VM_Id, Perc, SummaryType)

    VALUES ('2013-04-24', 1, 1, '0', '1')

    ;

    INSERT INTO Table_A

    (DeliveryDate, Pass, VM_Id, Perc, SummaryType)

    VALUES ('2013-04-25', 1, 1, '0', '1')

    ;

    INSERT INTO Table_A

    (DeliveryDate, Pass, VM_Id, Perc, SummaryType)

    VALUES ('2013-04-25', 0, 1, '0', '1')

    ;

    INSERT INTO Table_A

    (DeliveryDate, Pass, VM_Id, Perc, SummaryType)

    VALUES ('2013-04-25', 1, 1, '0', '1')

    ;

    INSERT INTO Table_A

    (DeliveryDate, Pass, VM_Id, Perc, SummaryType)

    VALUES ('2013-04-26', 1, 0, '0', '1')

    ;

    Can anyone help me to update either by:

    A. All rows

    B. In the 1st (top) instance of each DeliveryDate (In this example where Id = 1 or 2 or 4 or 7)

    Thanks in advance,

  • Quick attempt, any good?

    select a.*, ISNULL(b.result, 0)

    from [Table_A] as a

    OUTER APPLY ( SELECT DeliveryDate, MIN(ID) as ID, SUM(Pass) as Pass, SUM(VM_Id) as VM_ID,

    CASE WHEN SUM(VM_ID) > 0 THEN (SUM(Pass) / SUM(VM_Id)) *100 ELSE 0 END AS Result

    FROM [Table_A]

    WHERE SummaryType > 0

    AND a.ID = ID

    GROUP BY DeliveryDate) as b

    ---------------------------------------------------------

    It takes a minimal capacity for rational thought to see that the corporate 'free press' is a structurally irrational and biased, and extremely violent, system of elite propaganda.
    David Edwards - Media lens[/url]

    Society has varying and conflicting interests; what is called objectivity is the disguise of one of these interests - that of neutrality. But neutrality is a fiction in an unneutral world. There are victims, there are executioners, and there are bystanders... and the 'objectivity' of the bystander calls for inaction while other heads fall.
    Howard Zinn

  • Thanks Abu,

    But I need the Perc column to be updated to 67 where DeliveryDate = '2013-04-25'

    because ((2/3) * 100) = 66.6666 (rounded = 67).

    Thanks for your help though, πŸ™‚

  • What about this?

    select a.*, ISNULL(b.result, 0)

    from [Table_A] as a

    OUTER APPLY ( SELECT *

    FROM (SELECT DeliveryDate, MIN(ID) as ID, SUM(Pass) as Pass, SUM(VM_Id) as VM_ID,

    CASE WHEN SUM(VM_ID) > 0 THEN CAST(ROUND((SUM(Pass) / CAST(SUM(VM_Id) AS DECIMAL(5, 2))) * 100.00 , 0 ) AS INT) ELSE 0 END AS Result

    FROM [Table_A]

    WHERE SummaryType > 0

    GROUP BY DeliveryDate) AS bb

    WHERE a.ID = bb.ID) b

    A bit lazy with the coding though, I'm sure there is a better way to do the conversions to decimals etc but this should get you what you want hopefully!

    ---------------------------------------------------------

    It takes a minimal capacity for rational thought to see that the corporate 'free press' is a structurally irrational and biased, and extremely violent, system of elite propaganda.
    David Edwards - Media lens[/url]

    Society has varying and conflicting interests; what is called objectivity is the disguise of one of these interests - that of neutrality. But neutrality is a fiction in an unneutral world. There are victims, there are executioners, and there are bystanders... and the 'objectivity' of the bystander calls for inaction while other heads fall.
    Howard Zinn

  • -- check the query

    SELECT *, UpdateMe = CASE WHEN a.SummaryType <> '0' THEN 'Y' ELSE 'N' END

    FROM Table_A a

    OUTER APPLY (

    SELECT Result = (SUM(ai.Pass)/NULLIF(SUM(ai.VM_Id)*1.0,0)) * 100

    FROM Table_A ai

    WHERE ai.SummaryType <> '0'

    AND ai.DeliveryDate = a.DeliveryDate

    ) x

    -- check the query gain

    SELECT *, UpdateMe = CASE WHEN a.SummaryType <> '0' THEN 'Y' ELSE 'N' END

    FROM Table_A a

    CROSS APPLY (

    SELECT Result = (SUM(ai.Pass)/NULLIF(SUM(ai.VM_Id)*1.0,0)) * 100

    FROM Table_A ai

    WHERE ai.SummaryType <> '0'

    AND ai.DeliveryDate = a.DeliveryDate

    ) x

    WHERE a.SummaryType <> '0'

    -- if it works, run the update

    UPDATE a SET Perc = ISNULL(x.Result,0) -- do your rounding here

    FROM Table_A a

    CROSS APPLY (

    SELECT Result = (SUM(ai.Pass)/NULLIF(SUM(ai.VM_Id)*1.0,0)) * 100

    FROM Table_A ai

    WHERE ai.SummaryType <> '0'

    AND ai.DeliveryDate = a.DeliveryDate

    ) x

    WHERE a.SummaryType <> '0'

    SELECT * FROM Table_A

    β€œWrite the query the simplest way. If through testing it becomes clear that the performance is inadequate, consider alternative query forms.” - Gail Shaw

    For fast, accurate and documented assistance in answering your questions, please read this article.
    Understanding and using APPLY, (I) and (II) Paul White
    Hidden RBAR: Triangular Joins / The "Numbers" or "Tally" Table: What it is and how it replaces a loop Jeff Moden

  • Was waiting for your solution πŸ˜€ Nice!

    ---------------------------------------------------------

    It takes a minimal capacity for rational thought to see that the corporate 'free press' is a structurally irrational and biased, and extremely violent, system of elite propaganda.
    David Edwards - Media lens[/url]

    Society has varying and conflicting interests; what is called objectivity is the disguise of one of these interests - that of neutrality. But neutrality is a fiction in an unneutral world. There are victims, there are executioners, and there are bystanders... and the 'objectivity' of the bystander calls for inaction while other heads fall.
    Howard Zinn

  • Abu Dina (4/25/2013)


    Was waiting for your solution πŸ˜€ Nice!

    Thank you! πŸ™‚

    β€œWrite the query the simplest way. If through testing it becomes clear that the performance is inadequate, consider alternative query forms.” - Gail Shaw

    For fast, accurate and documented assistance in answering your questions, please read this article.
    Understanding and using APPLY, (I) and (II) Paul White
    Hidden RBAR: Triangular Joins / The "Numbers" or "Tally" Table: What it is and how it replaces a loop Jeff Moden

  • Thanks guys (Abu + ChrisM@Work)

    The update looks good to go!!

Viewing 8 posts - 1 through 7 (of 7 total)

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