Click here to monitor SSC
SQLServerCentral is supported by Redgate
 
Log in  ::  Register  ::  Not logged in
 
 
 


UPDATE from CTE


UPDATE from CTE

Author
Message
2Tall
2Tall
Say Hey Kid
Say Hey Kid (702 reputation)Say Hey Kid (702 reputation)Say Hey Kid (702 reputation)Say Hey Kid (702 reputation)Say Hey Kid (702 reputation)Say Hey Kid (702 reputation)Say Hey Kid (702 reputation)Say Hey Kid (702 reputation)

Group: General Forum Members
Points: 702 Visits: 1203
Hi. I have a CTE that returns 2 cost values.


WITH UpdateAverageLabourCost (ProductId,OH,Labour) AS

(
SELECT
AC.ProductId,
AC.OH,
AC.AVGDirectLabour + MAN + SUB - OH AS Labour

FROM dbo.AVGCost AC
INNER JOIN dbo.Products p ON AC.ProductId = p.CrossReference
WHERE Type <> 'P' AND AVGDirectLabour >0
)

UPDATE dbo.Products
SET Products.SLC = Labour
SET Products.SOC = OH
FROM
UpdateAverageLabourCost
WHERE Products.CrossReference = UpdateAverageLabourCost.ProductId



Is it possible to UPDATE multiple fields in one hit?
Currently if I run as is I receive error 'incorrect syntax near the keyword 'SET' (I tried adding a , at the end of the first SET)

I am able to run individually OK by commenting out one of the SETs after the UPDATE.

Can anyone help me out with the correct syntax if this is possible?

Regards,
Phil.

-------------------------------------------------------------------------------------
A neutron walks into a bar. "I'd like a beer" he says. The bartender promptly serves up a beer. "How much will that be?" asks the neutron. "For you?" replies the bartender, "no charge."

Two hydrogen atoms walk into a bar. One says, 'I think I've lost an electron.' The other says 'Are you sure?' The first says, 'Yes, I'm positive... '

Tommy Cooper

Piotr.Rodak
Piotr.Rodak
SSC Eights!
SSC Eights! (802 reputation)SSC Eights! (802 reputation)SSC Eights! (802 reputation)SSC Eights! (802 reputation)SSC Eights! (802 reputation)SSC Eights! (802 reputation)SSC Eights! (802 reputation)SSC Eights! (802 reputation)

Group: General Forum Members
Points: 802 Visits: 1761
You write SET only once in update clause:

WITH UpdateAverageLabourCost (ProductId,OH,Labour) AS
(
SELECT
AC.ProductId,
AC.OH,
AC.AVGDirectLabour + MAN + SUB - OH AS Labour

FROM dbo.AVGCost AC
INNER JOIN dbo.Products p ON AC.ProductId = p.CrossReference
WHERE Type <> 'P' AND AVGDirectLabour >0
)

UPDATE dbo.Products
SET Products.SLC = Labour,
   Products.SOC = OH
FROM
UpdateAverageLabourCost
WHERE Products.CrossReference = UpdateAverageLabourCost.ProductId




Regards

Piotr

...and your only reply is slàinte mhath
2Tall
2Tall
Say Hey Kid
Say Hey Kid (702 reputation)Say Hey Kid (702 reputation)Say Hey Kid (702 reputation)Say Hey Kid (702 reputation)Say Hey Kid (702 reputation)Say Hey Kid (702 reputation)Say Hey Kid (702 reputation)Say Hey Kid (702 reputation)

Group: General Forum Members
Points: 702 Visits: 1203
Thanks, not a million miles away from getting one right! Smile
Phil.

-------------------------------------------------------------------------------------
A neutron walks into a bar. "I'd like a beer" he says. The bartender promptly serves up a beer. "How much will that be?" asks the neutron. "For you?" replies the bartender, "no charge."

Two hydrogen atoms walk into a bar. One says, 'I think I've lost an electron.' The other says 'Are you sure?' The first says, 'Yes, I'm positive... '

Tommy Cooper

ChrisM@Work
ChrisM@Work
SSCrazy Eights
SSCrazy Eights (8.9K reputation)SSCrazy Eights (8.9K reputation)SSCrazy Eights (8.9K reputation)SSCrazy Eights (8.9K reputation)SSCrazy Eights (8.9K reputation)SSCrazy Eights (8.9K reputation)SSCrazy Eights (8.9K reputation)SSCrazy Eights (8.9K reputation)

Group: General Forum Members
Points: 8949 Visits: 19009
Philip Horan (1/5/2009)
Thanks, not a million miles away from getting one right! Smile
Phil.


Rewritten without the CTE it's much easier on the eye...
UPDATE p SET 
   SLC = (AC.AVGDirectLabour + AC.MAN + AC.SUB - AC.OH),
   SOC = AC.OH
FROM dbo.Products p
INNER JOIN dbo.AVGCost AC ON AC.ProductId = p.CrossReference
WHERE Type <> 'P' AND AVGDirectLabour >0



Note the use of "UPDATE p", and also that the table which is the UPDATE target is referenced as the FROM table.There are many possible ways to lay out this type of update, and some of them are known to be performance killers. The best known is where the UPDATE target is not the FROM table but is referenced as an explicit JOIN.

“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
2Tall
2Tall
Say Hey Kid
Say Hey Kid (702 reputation)Say Hey Kid (702 reputation)Say Hey Kid (702 reputation)Say Hey Kid (702 reputation)Say Hey Kid (702 reputation)Say Hey Kid (702 reputation)Say Hey Kid (702 reputation)Say Hey Kid (702 reputation)

Group: General Forum Members
Points: 702 Visits: 1203
Chris I was just playing with the CTE concept as I am quite new to TSQL.
Moving forward part of the learning process is to know when to employ the correct method as a solution for the problem.
Many thanks for your input.
Phil

-------------------------------------------------------------------------------------
A neutron walks into a bar. "I'd like a beer" he says. The bartender promptly serves up a beer. "How much will that be?" asks the neutron. "For you?" replies the bartender, "no charge."

Two hydrogen atoms walk into a bar. One says, 'I think I've lost an electron.' The other says 'Are you sure?' The first says, 'Yes, I'm positive... '

Tommy Cooper

ChrisM@Work
ChrisM@Work
SSCrazy Eights
SSCrazy Eights (8.9K reputation)SSCrazy Eights (8.9K reputation)SSCrazy Eights (8.9K reputation)SSCrazy Eights (8.9K reputation)SSCrazy Eights (8.9K reputation)SSCrazy Eights (8.9K reputation)SSCrazy Eights (8.9K reputation)SSCrazy Eights (8.9K reputation)

Group: General Forum Members
Points: 8949 Visits: 19009
Philip Horan (1/5/2009)
Chris I was just playing with the CTE concept as I am quite new to TSQL.
Moving forward part of the learning process is to know when to employ the correct method as a solution for the problem.
Many thanks for your input.
Phil


Phil,
Best way to learn is to play. I'd never considered using a CTE in an UPDATE before, but right there's a new challenge - to find a scenario where a CTE is the right way to go. I reckon someone will post one within a day or so.
"part of the learning process is to know when to employ the correct method as a solution for the problem" - so you're an old git too, right? Smile

“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
RBarryYoung
RBarryYoung
SSCrazy Eights
SSCrazy Eights (9.4K reputation)SSCrazy Eights (9.4K reputation)SSCrazy Eights (9.4K reputation)SSCrazy Eights (9.4K reputation)SSCrazy Eights (9.4K reputation)SSCrazy Eights (9.4K reputation)SSCrazy Eights (9.4K reputation)SSCrazy Eights (9.4K reputation)

Group: General Forum Members
Points: 9436 Visits: 9517
Chris Morris (1/5/2009)
Philip Horan (1/5/2009)
Chris I was just playing with the CTE concept as I am quite new to TSQL.
Moving forward part of the learning process is to know when to employ the correct method as a solution for the problem.
Many thanks for your input.
Phil


Phil,
Best way to learn is to play. I'd never considered using a CTE in an UPDATE before, but right there's a new challenge - to find a scenario where a CTE is the right way to go. I reckon someone will post one within a day or so.

See that Update solution that I just posted in the "Cursors Be Gone" thread. It's got a derived table, that arguably could/should be a CTE: http://www.sqlservercentral.com/Forums/FindPost630181.aspx

-- RBarryYoung, (302)375-0451 blog: MovingSQL.com, Twitter: @RBarryYoung
Proactive Performance Solutions, Inc.
"Performance is our middle name."
ChrisM@Work
ChrisM@Work
SSCrazy Eights
SSCrazy Eights (8.9K reputation)SSCrazy Eights (8.9K reputation)SSCrazy Eights (8.9K reputation)SSCrazy Eights (8.9K reputation)SSCrazy Eights (8.9K reputation)SSCrazy Eights (8.9K reputation)SSCrazy Eights (8.9K reputation)SSCrazy Eights (8.9K reputation)

Group: General Forum Members
Points: 8949 Visits: 19009
RBarryYoung (1/5/2009)
See that Update solution that I just posted in the "Cursors Be Gone" thread. It's got a derived table, that arguably could/should be a CTE: http://www.sqlservercentral.com/Forums/FindPost630181.aspx

Thanks Barry, I missed that thread and it's got tons of useful info.
Your update applies the UPDATE directly to the derived table! I would have expected a join to be necessary between the base table and the derived table with the UPDATE applied to the base table. How interesting!

“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
RBarryYoung
RBarryYoung
SSCrazy Eights
SSCrazy Eights (9.4K reputation)SSCrazy Eights (9.4K reputation)SSCrazy Eights (9.4K reputation)SSCrazy Eights (9.4K reputation)SSCrazy Eights (9.4K reputation)SSCrazy Eights (9.4K reputation)SSCrazy Eights (9.4K reputation)SSCrazy Eights (9.4K reputation)

Group: General Forum Members
Points: 9436 Visits: 9517
Yeah, AFAIK, Derived Tables and CTEs work just like Views in that respect: as long as they follow the rules for writable Views, you can write through them.

-- RBarryYoung, (302)375-0451 blog: MovingSQL.com, Twitter: @RBarryYoung
Proactive Performance Solutions, Inc.
"Performance is our middle name."
2Tall
2Tall
Say Hey Kid
Say Hey Kid (702 reputation)Say Hey Kid (702 reputation)Say Hey Kid (702 reputation)Say Hey Kid (702 reputation)Say Hey Kid (702 reputation)Say Hey Kid (702 reputation)Say Hey Kid (702 reputation)Say Hey Kid (702 reputation)

Group: General Forum Members
Points: 702 Visits: 1203
Thanks guys and yes I am an old git Smile

Old Dogs, new tricks....possible?
Thanks,
Phil.

-------------------------------------------------------------------------------------
A neutron walks into a bar. "I'd like a beer" he says. The bartender promptly serves up a beer. "How much will that be?" asks the neutron. "For you?" replies the bartender, "no charge."

Two hydrogen atoms walk into a bar. One says, 'I think I've lost an electron.' The other says 'Are you sure?' The first says, 'Yes, I'm positive... '

Tommy Cooper

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