| ACC2000: How to Create Running Totals in a QueryID: Q208714 
 | 
This article demonstrates two methods that you can use to create a running
totals query. A running totals query is a query in which the total for each
record is a summation of that record and any previous records. This type of
query is useful for displaying cumulative totals over a group of records
(or over a period of time) in a graph or report.
   Field: AYear: DatePart("yyyy",[OrderDate])
   Total: Group By
   Sort: Ascending
   Show: Yes 
   Field: AMonth: DatePart("m",[OrderDate])
   Total: Group By
   Sort: Ascending
   Show: Yes 
   Field: RunTot: DSum("Freight","Orders","DatePart('m', _
          [OrderDate])<=" & [AMonth] & " And  DatePart('yyyy', _
          [OrderDate])<=" & [AYear] & "")
   Total: Expression
   Show: Yes 
   Field: FDate: Format([OrderDate],"mmm")
   Total: Group By
   Sort: Ascending
   Show: Yes 
   Field: DatePart("yyyy",[OrderDate])
   Total: Where
   Criteria: 1997
   Show: No 
   AYear    AMonth     RunTot       FDate
   --------------------------------------
   1997     1          2238.98      Jan
   1997     2          3840.43      Feb
   1997     3          5729.24      Mar
   1997     4          8668.34      Apr
   1997     5          12129.74     May
   1997     6          13982.39     Jun
   1997     7          17729.29     Jul
   1997     8          22204.73     Aug
   1997     9          26565.26     Sep
   1997     10         32031.38     Oct
   1997     11         36192.09     Nov
   1997     12         42748.64     Dec 
   Field: EmpAlias: EmployeeID
   Total: Group By
   Show: Yes 
   Field: Freight
   Total: Sum
   Show: Yes 
   Field: RunTot: Format(DSum("Freight","Orders","[EmployeeID]<=" _
          & [EmpAlias] & ""),"$0,000.00")
   Total: Expression
   Show: Yes 
   Employee              SumOfFreight     RunTot
   -------------------------------------------------
   Davolio, Nancy        $8,836.64        $8,836.64
   Fuller, Andrew        $8,696.41        $17,533.05
   Leverling,Janet       $10,884.74       $28,417.79
   Peacock, Margaret     $11,346.14       $39,763.93
   Buchanan, Steven      $3,918.71        $43,682.64
   Suyama, Michael       $3,780.47        $47,463.11
   King, Robert          $6,665.44        $54,128.55
   Callahan, Laura       $7,487.88        $61,616.43
   Dodsworth, Anne       $3,326.26        $64,942.69 For more information about totals queries, click Microsoft Access Help on the 
Help menu, type perform calculations in a query in the Office Assistant or the Answer Wizard, 
and then click Search to view the topics returned.
Additional query words:
Keywords          : kbdta QryTotal QryHowto 
Version           : WINDOWS:2000
Platform          : WINDOWS 
Issue type        : kbhowto Last Reviewed: July 19, 1999