Click here to Skip to main content
Click here to Skip to main content
Alternative Tip/Trick

Applying Running Total to a Result set

, 14 May 2012 CPOL
Rate this:
Please Sign up or sign in to vote.
This is an alternative for "Applying Running Total to a Result set"

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.

-- Fetch the data using correlated scalar
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

-- Fetch the data using group by
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       

License

This article, along with any associated source code and files, is licensed under The Code Project Open License (CPOL)

Share

About the Author

Mika Wendelius
Architect
Finland Finland
I've been a programmer since mid 80's using languages like assembler, C/C++, PL/I (mainframe environment), pascal, VB (I know, I know, no comments please) and C# and utilizing different techniques and tools.
 
However I'm specialized in databases and database modeling. Mostly I have used products like Oracle (from version 6), SQL Server (from version 4.2), DB2 and Solid Server (nowadays an IBM product).
 
For the past 10+ years my main concerns have been dealing with different business processes and how to create software to implement and improve them. At my spare time (what ever that actually means) I'm also teaching and consulting on different areas of database management, development and database oriented software design.

Comments and Discussions

 
QuestionAlways useful PinmvpMehdi Gholam14-May-12 22:18 
AnswerRe: Always useful PinmvpMika Wendelius16-May-12 6:38 

General General    News News    Suggestion Suggestion    Question Question    Bug Bug    Answer Answer    Joke Joke    Rant Rant    Admin Admin   

Use Ctrl+Left/Right to switch messages, Ctrl+Up/Down to switch threads, Ctrl+Shift+Left/Right to switch pages.

| Advertise | Privacy | Terms of Use | Mobile
Web03 | 2.8.141220.1 | Last Updated 14 May 2012
Article Copyright 2012 by Mika Wendelius
Everything else Copyright © CodeProject, 1999-2014
Layout: fixed | fluid