If the expression in the calculated control does not include another
aggregate function, you can sum the expression by repeating it in the
report or group footer section and taking its sum. If the expression does
include another aggregate function, repeating the expression does not work
because Microsoft Access cannot sum a sum. Instead, use a running sum or a
function to hold the results.
To demonstrate the three methods, this article uses a report based on the
Order Details table in the sample database Northwind.mdb.
NOTE: For calculating totals in a page footer section, use only methods two and three.
Creating the Report
To create the report, follow these steps:
- Open the sample database Northwind.mdb.
- Create a report based on the Order Details table in Design View.
- Create an OrderID group by clicking Sorting And Grouping on the View menu, and then entering the following information in the Sorting And Grouping dialog box:
Field/Expression: OrderID
Group Header: Yes
Group Footer: Yes
- Add a report header and footer section to the report by clicking Report Header/Footer on the View menu.
Method 1: Summing Expressions That Do Not Contain Aggregate Functions
To sum a calculation that does not contain an aggregate function, repeat
the calculation with the
Sum() function. To use this method, follow
these steps:
- Add a text box control to the report's detail section to calculate the product of two fields. Set the control's properties as follows:
Name: Extended Price
ControlSource: =[UnitPrice] * [Quantity]
- Add a text box control in the OrderID group footer section to calculate the total for the group. Set the following properties for the control:
Name: Order Total
ControlSource: =Sum([UnitPrice] * [Quantity])
- Add a text box control in the report's footer section to calculate the total for the report. Set the following properties for the control:
Name: Report Total
ControlSource: =Sum([UnitPrice] * [Quantity])
- Preview the report to see the sum of the calculation.
Method 2: Summing Expressions That Contain Aggregate Functions
You can use a running sum to calculate totals for expressions that
contain aggregate functions or that reference other controls. To use
this method, follow these steps:
- Add a text box control to the report's OrderID group footer section to calculate a control that charges freight only when the order is over $100. Set the following properties for the control.
NOTE: In the following example, an underscore (_) at the end of a line is used as a line-continuation character. Remove the underscore from the end of the line when re-creating this example.
Name: Freight
ControlSource: =IIf(Sum([UnitPrice]*[Quantity])>100,0.05* _
Sum([UnitPrice]*[Quantity]),0)
- Add a second text box control to the report's Order ID group footer section to calculate the running sum for this control. Set the following properties for the control.
NOTE: In the following example, an underscore (_) at the end of a line is used as a line-continuation character. Remove the underscore from the end of the line when re-creating this example.
Name: FreightRunSum
ControlSource: =IIf(Sum([UnitPrice]*[Quantity])>100,0.05* _
Sum([UnitPrice]*[Quantity]),0)
RunningSum: Over Group
Visible: No
NOTE: When you test a running sum, set the Visible property to Yes to verify that the control is accumulating. Once you verify that it does, hide the control by setting the Visible property to No. - Add a text box control to the report's footer section to display the total by referencing the RunningSum property. Set the following properties for the control:
Name: Freight Total
ControlSource: =[FreightRunSum]
- Preview the report to see the sum of the calculation.
Method 3: Summing Controls Calculated by Functions
If you use code to calculate a control, you must use a function to
calculate its sum. You need the function to hold the results of the
calculation across the records. To use this method, follow these steps:
Microsoft provides programming examples for illustration only, without warranty either expressed or implied. This includes, but is not limited to, the implied warranties of merchantability or fitness for a particular purpose. This article assumes that you are familiar with the programming language that is being demonstrated and with the tools that are used to create and to debug procedures. Microsoft support engineers can help explain the functionality of a particular procedure, but they will not modify these examples to provide added functionality or construct procedures to meet your specific requirements.
- Create a new module and enter the following code in the Declarations section:
Option Explicit
Dim OrderTotal As Double ' Used for group total.
Dim GrandTotal As Double ' Used for report total.
- Add the following procedure to calculate the product of two fields:
Function CalcProduct (R as Report)
Dim tmpAmount As Double
tmpAmount = R![UnitPrice] * R![Quantity]
' Remember the total for the group.
OrderTotal = OrderTotal + tmpAmount
' Remember the total for the report.
GrandTotal = GrandTotal + tmpAmount
CalcProduct = tmpAmount
End Function
- Add the following procedure to initialize the report's variables to 0:
Function InitVars ()
OrderTotal = 0
GrandTotal = 0
End Function
- Add the following procedure to retrieve the total for the group:
Function GetGroupTotal ()
GetGroupTotal = OrderTotal
' Reset the variable to 0 for next group.
OrderTotal = 0
End Function
- Add the following procedure to retrieve the total for the report:
Function GetReportTotal ()
GetReportTotal = GrandTotal
End Function
- To initialize the variables to 0, set the report's OnOpen property as follows:
and then add three text box controls to the report's detail section. Set the following properties for the text boxes:
Text box 1:
Name: UnitPrice
ControlSource: UnitPrice
Text box 2:
Name: Quantity
ControlSource: Quantity
Text box 3:
Name: TheProduct
ControlSource: =CalcProduct([Report])
- Add a text box control to the group footer section to display the total for the group. Set the following properties for the control:
Name: GroupTotal
ControlSource: =GetGroupTotal()
- Add a text box control to the report's footer section to display the total for the report. Set the following properties for the control:
Name: ReportTotal
ControlSource: =GetReportTotal()
- Preview the report to see the sum of the calculation.