You can use the DSum functions to calculate the sum of a set of values in a specified set of records (domain). Use DSum in a macro or module, in a query expression, or in a calculated control.
For example, you could use DSum in a calculated field expression in a query to calculate the total sales made by a particular employee over a period of time. Or you could use DSum in a calculated control to display a running sum of sales for a particular product.
DSum(expr, domain[, criteria])
The DSum function uses the following arguments.
Argument | Description |
expr | Expression that identifies the numeric field whose values you want to sum. It can be a string expression identifying a field in a table or query, or it can be an expression that performs a calculation on data in that field. You can include in expr the name of a table field, a control on a form, a constant, or a function. If expr includes a function, it can be either built-in or user-defined, but not another domain aggregate or SQL aggregate function. |
domain | String expression identifying the set of records that constitutes the domain. It can be a table name or a query name. |
criteria | Optional string expression used to restrict the range of data on which DSum is performed. For example, criteria is often equivalent to the WHERE clause in an SQL expression, without the word WHERE. If criteria is omitted, DSum evaluates expr against the entire domain. Any field included in criteria must also be a field in domain; otherwise, DSum returns a Null. |
DSum finds the sum of values in the field or expression defined by expr, in the table or query referred to by domain, according to any restrictions specified by criteria.
If no record satisfies the criteria argument or if domain contains no records, DSum returns a Null.
Whether you use DSum in a macro or module, a query expression, or a calculated control, you must construct the criteria argument carefully to ensure that it will be evaluated correctly.
You can use DSum to specify criteria in the Criteria row of a query, in a calculated field in a query expression, or in the Update To row of an update query.
Note You can use either DSum or Sum in a calculated field expression in a totals query. If you use DSum, values are calculated before data is grouped. If you use Sum, the data is grouped before values in the field expression are evaluated.
You may want to use DSum when you need to display the sum of a set of values from a field that is not in the record source for your form or report. For example, suppose you have a form which displays information about a particular product. You could use DSum to maintain a running total of sales of that product in a calculated control.
Tip If you need to maintain a running total in a control on a report, you can use the RunningSum property of that control if the field on which it is based is included in the record source for the report. Use DSum to maintain a running sum on a form.
Note Unsaved changes to records in domain are not included when you use this function. If you want the DSum function to be based on the changed values, you must first save the changes by choosing the Save Record command from the File menu, moving the focus to another record, or using the Update method.
DCount Function, Domain Aggregate Functions, RunningSum Property.
This example totals the values from the Freight field for orders shipped to the United Kingdom. The domain is an Orders table. The criteria argument restricts the resulting set of records to those for which ShipCountry equals UK.
Dim curX As Currency= DSum("[Freight]", "Orders", "[ShipCountry] = 'UK'")
The next example calculates a total using two separate criteria. Note that single quotation marks (') and number signs (#) are included in the string expression, so that when the strings are concatenated, the string literal will be enclosed in single quotation marks, and the date will be enclosed in number signs.
Dim curX As Currency= DSum("[Freight]", "Orders", _ "[ShipCountry] = 'UK' AND [ShippedDate] > #1-1-95#")
You can use a domain function in the Update To row of an update query. For instance, suppose you want to track current sales by product in a Products table. You could add a new field called SalesSoFar to the Products table, and run an update query to calculate the correct values and update the records. Create a new query based on the Products table, and choose Update from the Query menu. Add the SalesSoFar field to the query grid, and enter the following in the Update To row:
DSum("[Quantity]*[UnitPrice]", "Order Details", _ "[ProductID] = " & [ProductID])
When the query is run, Microsoft Access calculates the total amount of sales for each product, based on information from an Order Details table. The sum of sales for each product is added to the Products table.