SQL Clone
SQLServerCentral is supported by Redgate
 
Log in  ::  Register  ::  Not logged in
 
 
 


column update based on calculation and group by


column update based on calculation and group by

Author
Message
DerbyNeal
DerbyNeal
Old Hand
Old Hand (302 reputation)Old Hand (302 reputation)Old Hand (302 reputation)Old Hand (302 reputation)Old Hand (302 reputation)Old Hand (302 reputation)Old Hand (302 reputation)Old Hand (302 reputation)

Group: General Forum Members
Points: 302 Visits: 909
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,
Abu Dina
Abu Dina
Ten Centuries
Ten Centuries (1.2K reputation)Ten Centuries (1.2K reputation)Ten Centuries (1.2K reputation)Ten Centuries (1.2K reputation)Ten Centuries (1.2K reputation)Ten Centuries (1.2K reputation)Ten Centuries (1.2K reputation)Ten Centuries (1.2K reputation)

Group: General Forum Members
Points: 1239 Visits: 3323
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

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
DerbyNeal
DerbyNeal
Old Hand
Old Hand (302 reputation)Old Hand (302 reputation)Old Hand (302 reputation)Old Hand (302 reputation)Old Hand (302 reputation)Old Hand (302 reputation)Old Hand (302 reputation)Old Hand (302 reputation)

Group: General Forum Members
Points: 302 Visits: 909
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, :-)
Abu Dina
Abu Dina
Ten Centuries
Ten Centuries (1.2K reputation)Ten Centuries (1.2K reputation)Ten Centuries (1.2K reputation)Ten Centuries (1.2K reputation)Ten Centuries (1.2K reputation)Ten Centuries (1.2K reputation)Ten Centuries (1.2K reputation)Ten Centuries (1.2K reputation)

Group: General Forum Members
Points: 1239 Visits: 3323
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

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
ChrisM@Work
ChrisM@Work
SSCoach
SSCoach (16K reputation)SSCoach (16K reputation)SSCoach (16K reputation)SSCoach (16K reputation)SSCoach (16K reputation)SSCoach (16K reputation)SSCoach (16K reputation)SSCoach (16K reputation)

Group: General Forum Members
Points: 16262 Visits: 19551
-- 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
Exploring Recursive CTEs by Example Dwain Camps
Abu Dina
Abu Dina
Ten Centuries
Ten Centuries (1.2K reputation)Ten Centuries (1.2K reputation)Ten Centuries (1.2K reputation)Ten Centuries (1.2K reputation)Ten Centuries (1.2K reputation)Ten Centuries (1.2K reputation)Ten Centuries (1.2K reputation)Ten Centuries (1.2K reputation)

Group: General Forum Members
Points: 1239 Visits: 3323
Was waiting for your solution :-D 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

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
ChrisM@Work
ChrisM@Work
SSCoach
SSCoach (16K reputation)SSCoach (16K reputation)SSCoach (16K reputation)SSCoach (16K reputation)SSCoach (16K reputation)SSCoach (16K reputation)SSCoach (16K reputation)SSCoach (16K reputation)

Group: General Forum Members
Points: 16262 Visits: 19551
Abu Dina (4/25/2013)
Was waiting for your solution :-D 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
Exploring Recursive CTEs by Example Dwain Camps
DerbyNeal
DerbyNeal
Old Hand
Old Hand (302 reputation)Old Hand (302 reputation)Old Hand (302 reputation)Old Hand (302 reputation)Old Hand (302 reputation)Old Hand (302 reputation)Old Hand (302 reputation)Old Hand (302 reputation)

Group: General Forum Members
Points: 302 Visits: 909
Thanks guys (Abu + ChrisM@Work)

The update looks good to go!!
Go


Permissions

You can't post new topics.
You can't post topic replies.
You can't post new polls.
You can't post replies to polls.
You can't edit your own topics.
You can't delete your own topics.
You can't edit other topics.
You can't delete other topics.
You can't edit your own posts.
You can't edit other posts.
You can't delete your own posts.
You can't delete other posts.
You can't post events.
You can't edit your own events.
You can't edit other events.
You can't delete your own events.
You can't delete other events.
You can't send private messages.
You can't send emails.
You can read topics.
You can't vote in polls.
You can't upload attachments.
You can download attachments.
You can't post HTML code.
You can't edit HTML code.
You can't post IFCode.
You can't post JavaScript.
You can post emoticons.
You can't post or upload images.

Select a forum

































































































































































SQLServerCentral


Search