Introduction
Given the same data structures and data as in the original tip, the running total can be calculated also using a single statement.
Although the results would be the same, often using a single SQL statements gives better performance results. This is because the optimizer can more efficiently calculate the best plan to fetch the data. This optimization isn't possible over several statements since the optimizer isn't optimizing the 'general throughput' of a T-SQL block but the throughput of a single statement.
Variation 1, correlated scalar query
The first variation is to use a correlated scalar query.
SELECT A.ProductID,
A.[DATE],
A.QTY,
( SELECT SUM(B.QTY)
FROM
( SELECT ProductID, [DATE], QTY FROM GRN
UNION ALL
SELECT ProductID, [DATE], - (QTY) FROM Invoice
) AS B
WHERE B.ProductId = A.ProductId
AND B.[DATE] <= A.[DATE]
) AS RuningTotal
FROM ( SELECT ProductID, [DATE], QTY FROM GRN
UNION ALL
SELECT ProductID, [DATE], - (QTY) FROM Invoice
) AS A
ORDER BY A.[Date]
The outer body of the statement is the same as in the original tip. The difference is that for each row that is fetched frmo the two tables a scalar query is executed when the row is returned. In the scalar query the same base data is used, but the sum of QTY
is calculated only for the rows for the same or previous date and for the same product.
Variation 2, GROUP BY with join
A slighly different approach is to use a GROUP BY
clause and joining the data
SELECT A.ProductID,
A.[DATE],
A.QTY,
SUM(B.QTY) AS RuningTotal
FROM ( SELECT ProductID, [DATE], QTY FROM GRN
UNION ALL
SELECT ProductID, [DATE], - (QTY) FROM Invoice
) AS A,
( SELECT ProductID, [DATE], QTY FROM GRN
UNION ALL
SELECT ProductID, [DATE], - (QTY) FROM Invoice
) AS B
WHERE B.ProductId = A.ProductId
AND B.[DATE] <= A.[DATE]
GROUP BY A.ProductID,
A.[DATE],
A.QTY
ORDER BY A.[Date]
Basically the above is very much the same as variation 1. Only this time the same data is fetched twice (note, logically) and then each row from result set named A is joined to rows from results set B. The join condition is the same as previously: Same or earlier date for the same product.
What variation to use
There are also lots of other variations that could be written so what to use? Well, there's no one and only correct answer, it depends. It depends on factors like:
- Your data, this affects quite a lot. How much rows you have, what kind of statistical distribution there is for the data used in conditions and so on
- The plan, using actual (or predicted) data you should always check which variation yields the best results in terms of logical reads, CPU usage etc
- Maintainability, is this going to be hard to understand or to maintain later. If you're creating a massive piece of SQL it may be hard to understand by other people or even by yourself later. Sometimes it's better to break the problem into smaller, maintainable pieces and sometimes to squeeze all the power from the database.
History
- 14th May, 2012: Alternative created