Cumulative sums within groups
Can another field be added to the question posed on 12 July 2002, Cumulative Sum In Access? I want to calculate cumulative sums for each group in my data. For example if I have the following data:
ltr nbr amount A 1 10 A 2 15 A 3 20 B 1 30 B 2 35 B 3 40
my result should be:
ltr nbr sumamt A 1 10 A 2 25 A 3 40 B 1 30 B 2 65 B 3 105
Yes, there are actually several ways to do this.
The first method, which only works in Access (and which I really should have mentioned in that earlier answer, despite my desire to write answers in standard SQL whenever possible), uses the proprietary Access DSUM function:
select ltr , nbr , dsum("amount" ,"yourtable" ,"ltr = '" & ltr & "' AND nbr <= " & nbr ) as sumamt from yourtable
Note the DSUM function takes three parameters -- a column, a table, and a condition, all of which must be quoted. Quoting the condition is tricky if you also have to quote values within it, so be careful; use doublequotes for parameter quoting and singlequotes for value quoting. DSUM is most often used for running totals within the same table, as in this case, but it can just as easily reference other tables.
The second method, the method shown in my earlier answer, uses a correlated subquery in the SELECT list:
select t1.ltr , t1.nbr , ( select sum(amount) from yourtable where ltr = t1.ltr and nbr <= t1.nbr ) as sumamt from yourtable t1
Notice how closely it resembles the DSUM solution. The correlated subquery will work in all standard databases including Access.
The third method uses a join:
select t1.ltr , t1.nbr , sum(t2.amount) as sumamt from yourtable t1 inner join yourtable t2 on t1.ltr = t2.ltr and t1.nbr >= t2.nbr group by t1.ltr , t1.nbr
Note that a correlated subquery is logically equivalent to a join anyway, so feel free to code your query whichever way is easiest for you to understand.