In the previous post I shown how to use the newly introduced WINDOW clause in SQL Server 2022 by providing some historical context concerning what it took to do the same simple aggregations as SUM or AVG within previous versions of SQL Server. Let's look at another scenario based on the previously created Sales.vSalesOrders view - using the same two functions in providing running totals.
A running total is a summation of a sequence of values (e.g. OrderQty) ordered by a key, typically one or more columns that uniquely define the sequence, something like a unique record identifier (e.g. SalesOrderId). Moreover, the running total can be defined within a partition (e.g. Year/Month).
In SQL Server 2000, to calculate the running total and average for a value within a partition would resume implementing the logic for each attribute in correlated subqueries. One needed thus one subquery for each attribute, resulting in multiple processing of the base tables. Even if the dataset was already in the memory, it still involves a major overhead.
-- running total/average based on correlated subquery (SQL Server 2000+) SELECT SOL.SalesOrderId , SOL.ProductId , SOL.OrderDate , SOL.[Year] , SOL.[Month] , SOL.OrderQty , (-- correlated subquery SELECT SUM(SRT.OrderQty) FROM Sales.vSalesOrders SRT WHERE SRT.ProductId = SOL.ProductId AND SRT.[Year] = SOL.[Year] AND SRT.[Month] = SOL.[Month] AND SRT.SalesOrderId <= SOL.SalesOrderId ) RunningTotalQty , (-- correlated subquery SELECT AVG(SRT.OrderQty) FROM Sales.vSalesOrders SRT WHERE SRT.ProductId = SOL.ProductId AND SRT.[Year] = SOL.[Year] AND SRT.[Month] = SOL.[Month] AND SRT.SalesOrderId <= SOL.SalesOrderId ) RunningAvgQty FROM Sales.vSalesOrders SOL WHERE SOL.ProductId IN (745) AND SOL.[Year] = 2012 AND SOL.[Month] BETWEEN 1 AND 3 ORDER BY SOL.SalesOrderId
Then SQL Server 2005 allowed consolidating the different correlated subqueries into one by using the CROSS APPLY join:
-- running total/average based on correlated subquery with CROSS APPLY (SQL Server 2005+) SELECT SOL.SalesOrderId , SOL.ProductId , SOL.OrderDate , SOL.[Year] , SOL.[Month] , SOL.OrderQty , SRT.RunningTotalQty , SRT.RunningAvgQty FROM Sales.vSalesOrders SOL CROSS APPLY (-- correlated subquery SELECT SUM(SRT.OrderQty) RunningTotalQty , AVG(SRT.OrderQty) RunningAvgQty FROM Sales.vSalesOrders SRT WHERE SRT.ProductId = SOL.ProductId AND SRT.[Year] = SOL.[Year] AND SRT.[Month] = SOL.[Month] AND SRT.SalesOrderId <= SOL.SalesOrderId ) SRT WHERE SOL.ProductId IN (745) AND SOL.[Year] = 2012 AND SOL.[Month] BETWEEN 1 AND 3 ORDER BY SOL.SalesOrderId
Even if SQL Server 2005 introduced window functions that work on a partition, an ORDER BY clause was supported only with SQL Server 2012:
-- running total/average based on window functions (SQL Server 2012+) SELECT SOL.SalesOrderId , SOL.ProductId , SOL.OrderDate , SOL.[Year] , SOL.[Month] , SOL.OrderQty , SUM(SOL.OrderQty) OVER (PARTITION BY SOL.ProductId, SOL.[Year], SOL.[Month] ORDER BY SOL.SalesOrderId) RunningTotalQty , AVG(SOL.OrderQty) OVER (PARTITION BY SOL.ProductId, SOL.[Year], SOL.[Month] ORDER BY SOL.SalesOrderId) RunningAvgQty FROM Sales.vSalesOrders SOL WHERE SOL.ProductId IN (745) AND SOL.[Year] = 2012 AND SOL.[Month] BETWEEN 1 AND 3 ORDER BY SOL.SalesOrderId
Now, in SQL Server 2022 the WINDOW clause allows simplifying the query as follows by defining the partition only once:
-- running total/average based on window functions and clause (SQL Server 2022+) SELECT SOL.SalesOrderId , SOL.ProductId , SOL.OrderDate , SOL.[Year] , SOL.[Month] , SOL.OrderQty , SUM(SOL.OrderQty) OVER SalesByMonth AS RunningTotalQty
, AVG(SOL.OrderQty) OVER SalesByMonth AS RunningAvgQty
FROM Sales.vSalesOrders SOL WHERE SOL.ProductId IN (745) AND SOL.[Year] = 2012 AND SOL.[Month] BETWEEN 1 AND 3 WINDOW SalesByMonth AS (PARTITION BY SOL.ProductId, SOL.[Year], SOL.[Month] ORDER BY SOL.SalesOrderId) ORDER BY SOL.SalesOrderId
Moreover, the WINDOW clause allows forward (and backward) referencing of one window into the other:
-- running total/average based on window functions and clause (SQL Server 2022+) SELECT SOL.SalesOrderId , SOL.ProductId , SOL.OrderDate , SOL.[Year] , SOL.[Month] , SOL.OrderQty -- simple aggregations , SUM(SOL.OrderQty) OVER SalesByMonth AS TotalQty
, AVG(SOL.OrderQty) OVER SalesByMonth AS AvgQty
-- running totals , SUM(SOL.OrderQty) OVER SalesByMonthSorted AS RunningTotalQty
, AVG(SOL.OrderQty) OVER SalesByMonthSorted AS RunningAvgQty
FROM Sales.vSalesOrders SOL WHERE SOL.ProductId IN (745) AND SOL.[Year] = 2012 AND SOL.[Month] BETWEEN 1 AND 3 WINDOW SalesByMonth AS (PARTITION BY SOL.ProductId, SOL.[Year], SOL.[Month]) , SalesByMonthSorted AS (SalesByMonth ORDER BY SOL.SalesOrderId) ORDER BY SOL.SalesOrderId
No comments:
Post a Comment