We typically use the UPDATE clause to update or change the existing data in a given table or view. Most business logic requires that the value of one or more variables is set based on this update. Generally, we find that these requirements are realized with two statements – an UPDATE, followed by a SELECT statement (or vice versa, as the case may be). However, a little known and therefore underappreciated feature of the UPDATE clause is that it can also be used to update variables. Here’s an example.
Assume that we have a requirement to update the order detail quantities in the [Sales].[SalesOrderDetail] table of the [AdventureWorks2012] database with a given value supplied in the variable @orderDetailQuantityIncrementBy. At the same time, we also need to know the amount by which the order value increased or decreased.
A typical implementation of this would be:
USE AdventureWorks2012; GO --Variable indicating the change in Order Quantity DECLARE @orderDetailQuantityIncrementBy INT = 1; --Temporary table variable to hold the before/after values DECLARE @orderUpdate TABLE (BeforeOrderQuantity INT, BeforeUnitPrice DECIMAL(20, 8), AfterOrderQuantity INT, AfterUnitPrice DECIMAL(20, 8) ); --Using a transaction so that we can return to the table's base state BEGIN TRANSACTION UpdateVariableTest; --Perform the update UPDATE so SET so.OrderQty += @orderDetailQuantityIncrementBy OUTPUT deleted.OrderQty, deleted.UnitPrice, inserted.OrderQty, inserted.UnitPrice INTO @orderUpdate (BeforeOrderQuantity, BeforeUnitPrice, AfterOrderQuantity, AfterUnitPrice) FROM Sales.SalesOrderDetail AS so WHERE so.SalesOrderID = 43659 AND so.SalesOrderDetailID IN (8, 10); --Calculate the change in order total SELECT SUM((ou.AfterOrderQuantity * ou.AfterUnitPrice) - (ou.BeforeOrderQuantity * ou.BeforeUnitPrice) ) AS orderAmountChanges FROM @orderUpdate AS ou; ROLLBACK TRANSACTION UpdateVariableTest; GO /*********** RESULTS ***********/ --orderAmountChanges -------------------- --34.54040000
As you can see, we used an UPDATE clause and collected the before/after update information in a temporary table variable. Later, we performed arithmetic operations on the value stored in the table variable.
Using a single UPDATE clause to update a variable
This requirement can be realized within a single UPDATE clause also. Here’s the modified solution:
USE AdventureWorks2012; GO --Variable indicating the change in Order Quantity DECLARE @orderDetailQuantityIncrementBy INT = 1; --Variable indicating the change in Order Amount DECLARE @orderAmountChanges DECIMAL(20,8) = 0; --Using a transaction so that we can return to the table's base state BEGIN TRANSACTION UpdateVariableTest; --Perform the update UPDATE so SET so.OrderQty += @orderDetailQuantityIncrementBy, @orderAmountChanges += (@orderDetailQuantityIncrementBy * so.UnitPrice) FROM Sales.SalesOrderDetail AS so WHERE so.SalesOrderID = 43659 AND so.SalesOrderDetailID IN (8, 10); --Fetch the value from the variable SELECT @orderAmountChanges AS OrderAmountChanges; ROLLBACK TRANSACTION UpdateVariableTest; GO /*********** RESULTS ***********/ --OrderAmountChanges -------------------- --34.54040000
As can be seen from the example above, the UPDATE clause makes realization of the said requirement very simple & readable.
Further Reading
Until we meet next time,