May 6, 2014 at 10:21 am
I have a stored procedure which updates a table with the code below.
It is rather slow (table with 360,000 rows).
Any suggestions?
Thanks,
Julian
-- ADD average FTE Hrs for the Week based table with daily data
UPDATE DRPDATA
SET FTEHrsAVG =
(
SELECTAVG(B.FTEHrs)
FROMDRPDATA B
WHEREA.MWID = B.MWID
AND
DATEPART(ISO_WEEK,A.BEGINDATUM)= DATEPART(ISO_WEEK,B.BEGINDATUM)
AND
A.[Org eenheid code] = B.[Org eenheid code]
AND
B.FlexVast = 'VAST'
GROUP BYB.MWID,b.[Org eenheid code], DATEPART(ISO_WEEK,B.BEGINDATUM)
)
FROMDRPDATA A;
May 6, 2014 at 10:35 am
that looks like an accidental cross join to me.
it explicitly says UPDATE DRPDATA, but since the FROM has the table name as being aliased,and the unaliased table is not referenced anywhere else, there is an implied cross join like this:
UPDATE DRPDATA
SET ....
FROM DRPDATA A ,DRPDATA
the UPDATE should be UPDATE ALIASNAME explicitly.
-- ADD average FTE Hrs for the Week based table with daily data
UPDATE A
SET A.FTEHrsAVG =
(
SELECTAVG(B.FTEHrs)
FROMDRPDATA B
WHEREA.MWID = B.MWID
AND
DATEPART(ISO_WEEK,A.BEGINDATUM)= DATEPART(ISO_WEEK,B.BEGINDATUM)
AND
A.[Org eenheid code] = B.[Org eenheid code]
AND
B.FlexVast = 'VAST'
GROUP BYB.MWID,b.[Org eenheid code], DATEPART(ISO_WEEK,B.BEGINDATUM)
)
FROMDRPDATA A;
Lowell
May 6, 2014 at 11:10 am
Some other things to consider:
1. Do you have indices on the join columns? (MWID, [Org Eenheid Code], BEGINDATUM)
2. If you have an index on BEGINDATUM, the expression
DATEPART(ISO_WEEK,A.BEGINDATUM)= DATEPART(ISO_WEEK,B.BEGINDATUM)
will stop SQL server from using that index (Since it's a function call it's not a SARG). To get around that, try to reformulate it as
BEGINDATUM > <beginning of the week> AND BEGINDATUM < <beginning of following week>
May 6, 2014 at 11:22 am
In this case I would consider using a temporary table
๐
May 6, 2014 at 11:30 am
Hello Lowell,
Thanks for your response.
For some reason the original code is 15 seconds faster (2.25 min iso 2.5 min)....
Cheers,
Julian
May 6, 2014 at 11:32 am
The code is part of a stored procedure which bulk inserts data from a csv file, using a Staging table.
Thanks for the hint. Job for later.
Cheers,
Julian
gbritton1 (5/6/2014)
Some other things to consider:1. Do you have indices on the join columns? (MWID, [Org Eenheid Code], BEGINDATUM)
2. If you have an index on BEGINDATUM, the expression
DATEPART(ISO_WEEK,A.BEGINDATUM)= DATEPART(ISO_WEEK,B.BEGINDATUM)
will stop SQL server from using that index (Since it's a function call it's not a SARG). To get around that, try to reformulate it as
BEGINDATUM > <beginning of the week> AND BEGINDATUM < <beginning of following week>
May 6, 2014 at 11:47 am
Without sample data to test against...
Try this.
;WITH Updater AS (
SELECT
FTEHrsAVG,
NewFTEHrsAVG = AVG(CASE WHEN FlexVast = 'VAST' THEN FTEHrs ELSE NULL END)
OVER(PARTITION BY MWID, [Org eenheid code], DATEPART(ISO_WEEK,A.BEGINDATUM))
FROM DRPDATA o
WHERE EXISTS (
SELECT 1 FROM DRPDATA i
WHERE i.MWID = o.MWID
AND DATEPART(ISO_WEEK,i.BEGINDATUM)= DATEPART(ISO_WEEK,o.BEGINDATUM)
AND i.[Org eenheid code] = o.[Org eenheid code]
AND i.FlexVast = 'VAST')
)
UPDATE Updater SET FTEHrsAVG = NewFTEHrsAVG
You might not need the EXISTS check, it depends on what you want to do with unaffected partitions.
If the number of affected rows is relatively high and unaffected partitions should have FTEHrsAVG set to NULL, then try without the EXISTS check - it should be very quick.
For better assistance in answering your questions, please read this[/url].
Hidden RBAR: Triangular Joins[/url] / The "Numbers" or "Tally" Table: What it is and how it replaces a loop[/url] Jeff Moden[/url]
May 6, 2014 at 2:04 pm
ChrisM@home (5/6/2014)
Without sample data to test against...Try this.
;WITH Updater AS (
SELECT
FTEHrsAVG,
NewFTEHrsAVG = AVG(CASE WHEN FlexVast = 'VAST' THEN FTEHrs ELSE NULL END)
OVER(PARTITION BY MWID, [Org eenheid code], DATEPART(ISO_WEEK,A.BEGINDATUM))
FROM DRPDATA o
WHERE EXISTS (
SELECT 1 FROM DRPDATA i
WHERE i.MWID = o.MWID
AND DATEPART(ISO_WEEK,i.BEGINDATUM)= DATEPART(ISO_WEEK,o.BEGINDATUM)
AND i.[Org eenheid code] = o.[Org eenheid code]
AND i.FlexVast = 'VAST')
)
UPDATE Updater SET FTEHrsAVG = NewFTEHrsAVG
You might not need the EXISTS check, it depends on what you want to do with unaffected partitions.
If the number of affected rows is relatively high and unaffected partitions should have FTEHrsAVG set to NULL, then try without the EXISTS check - it should be very quick.
That is amazing. Would you perhaps have a reference to other examples of CTE usage like these?
May 7, 2014 at 2:21 am
Bouke Bruinsma (5/6/2014)
ChrisM@home (5/6/2014)
Without sample data to test against...Try this.
;WITH Updater AS (
SELECT
FTEHrsAVG,
NewFTEHrsAVG = AVG(CASE WHEN FlexVast = 'VAST' THEN FTEHrs ELSE NULL END)
OVER(PARTITION BY MWID, [Org eenheid code], DATEPART(ISO_WEEK,A.BEGINDATUM))
FROM DRPDATA o
WHERE EXISTS (
SELECT 1 FROM DRPDATA i
WHERE i.MWID = o.MWID
AND DATEPART(ISO_WEEK,i.BEGINDATUM)= DATEPART(ISO_WEEK,o.BEGINDATUM)
AND i.[Org eenheid code] = o.[Org eenheid code]
AND i.FlexVast = 'VAST')
)
UPDATE Updater SET FTEHrsAVG = NewFTEHrsAVG
You might not need the EXISTS check, it depends on what you want to do with unaffected partitions.
If the number of affected rows is relatively high and unaffected partitions should have FTEHrsAVG set to NULL, then try without the EXISTS check - it should be very quick.
That is amazing. Would you perhaps have a reference to other examples of CTE usage like these?
Thanks. That's why I lurk here - to learn stuff like this. It's what I'd recommend to you too. When something interesting or new comes up, copy it and pull it apart locally to see how it works - and if you can improve on it.
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
May 7, 2014 at 1:42 pm
I totally agree. I pick up something useful everytime I browse around the forums. And I could give quite a bit of examples of practical usage in my work of stuff I learned here.
So yeah, i'll be lurking the forums.
May 8, 2014 at 5:18 am
Hello Chris,
Thank you very much!
It is ligthning fast (4 sec a.o.t. 1.5 min).
Cheers,
Julian
ChrisM@home (5/6/2014)
Without sample data to test against...Try this.
;WITH Updater AS (
SELECT
FTEHrsAVG,
NewFTEHrsAVG = AVG(CASE WHEN FlexVast = 'VAST' THEN FTEHrs ELSE NULL END)
OVER(PARTITION BY MWID, [Org eenheid code], DATEPART(ISO_WEEK,A.BEGINDATUM))
FROM DRPDATA o
WHERE EXISTS (
SELECT 1 FROM DRPDATA i
WHERE i.MWID = o.MWID
AND DATEPART(ISO_WEEK,i.BEGINDATUM)= DATEPART(ISO_WEEK,o.BEGINDATUM)
AND i.[Org eenheid code] = o.[Org eenheid code]
AND i.FlexVast = 'VAST')
)
UPDATE Updater SET FTEHrsAVG = NewFTEHrsAVG
You might not need the EXISTS check, it depends on what you want to do with unaffected partitions.
If the number of affected rows is relatively high and unaffected partitions should have FTEHrsAVG set to NULL, then try without the EXISTS check - it should be very quick.
Viewing 11 posts - 1 through 10 (of 10 total)
You must be logged in to reply to this topic. Login to reply