ACC2000: Sample Function to Create a Running Sum on a Form
ID: Q210338
|
The information in this article applies to:
Moderate: Requires basic macro, coding, and interoperability skills.
SUMMARY
This article shows you how to create a sample user-defined function to
compute a running sum on a form.
MORE INFORMATION
One way to compute a running sum on a form is to use the DSum() function. For additional information about how to use the DSum() function to compute a running sum on a form, please see the following
article in the Microsoft Knowledge Base:
Q210495 ACC2000: How to Use DSum to Create a Running Sum on a Form
Using the method demonstrated in this article has the following advantages
over using the DSum() function:
- The method demonstrated in this article does not require a sequential ID field. A required sequential ID field limits you to computing a running sum using a single ordering of your records.
- Using the method demonstrated in this article is significantly faster than using the DSum() function to compute a running sum.
How to Create and Use the RunSum() Function
Microsoft provides programming examples for illustration only, without warranty
either expressed or implied, including, but not limited to, the implied warranties of
merchantability and/or fitness for a particular purpose. This article assumes that you
are familiar with the programming language being demonstrated and the tools used to
create and debug procedures. Microsoft support professionals 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 needs. If you have limited
programming experience, you may want to contact a Microsoft Certified Solution Provider
or the Microsoft fee-based consulting line at (800) 936-5200. For more information about
Microsoft Certified Solution Providers, please see the following page on the World Wide Web:
http://www.microsoft.com/mcsp/
For more information about the support options available from Microsoft, please see the
following page on the World Wide Web:
http://www.microsoft.com/support/supportnet/overview/overview.asp NOTE: The sample code in this article uses Microsoft Data Access
Objects. For this code to run properly, you need to reference
the Microsoft DAO 3.6 Object Library.
- Open the sample database Northwind.mdb. Create a new module, and type the following line in the Declarations section if it is not already there:
Option Explicit
- Type the following code in the module:
Function RunSum (F As Form, KeyName As String, KeyValue, _
FieldToSum As String)
'***********************************************************
' FUNCTION: RunSum()
' PURPOSE: Compute a running sum on a form.
' PARAMETERS:
' F - The form containing the previous value to
' retrieve.
' KeyName - The name of the form's unique key field.
' KeyValue - The current record's key value.
' FieldToSum - The name of the field in the previous
' record containing the value to retrieve.
' RETURNS: A running sum of the field FieldToSum.
' EXAMPLE: =RunSum(Form,"ID",[ID],"Amount")
'***********************************************************
Dim RS As DAO.Recordset
Dim Result
On Error GoTo Err_RunSum
' Get the form Recordset.
Set RS = F.RecordsetClone
' Find the current record.
Select Case RS.Fields(KeyName).Type
' Find using numeric data type key value?
Case DB_INTEGER, DB_LONG, DB_CURRENCY, _
DB_SINGLE, DB_DOUBLE, DB_BYTE
RS.FindFirst "[" & KeyName & "] = " & KeyValue
' Find using date data type key value?
Case DB_DATE
RS.FindFirst "[" & KeyName & "] = #" & KeyValue & "#"
' Find using text data type key value?
Case DB_TEXT
RS.FindFirst "[" & KeyName & "] = '" & KeyValue & "'"
Case Else
MsgBox "ERROR: Invalid key field data type!"
GoTo Bye_RunSum
End Select
' Compute the running sum.
Do Until RS.BOF
Result = Result + RS(FieldToSum)
' Move to the previous record.
RS.MovePrevious
Loop
Bye_RunSum:
RunSum = Result
Exit Function
Err_RunSum:
Resume Bye_RunSum
End Function
- Create the following new query based on the Orders table and the Order Subtotals query. Save the query as qryOrders:
Query: qryOrders
------------------------------------------------------
Type: select query
Join: Orders.[OrderID] <->; [Order Subtotals].[OrderID]
Field: OrderID
Table: Orders
Sort: Ascending
Field: Subtotal
Table: Order Subtotals
- Use the Form Wizard to create a new form based on the qryOrders query. Include both fields on the form. On the next screen click Tabular.
- Add a text box with the following properties to the new form:
Name: RunningSum
ControlSource: =RunSum([Form],"OrderID",[OrderID],"Subtotal")
Format: Currency
- Save the form and then view it in Form view.
- Select different records using the record selector. Note that the RunningSum field shows an accumulated total based on the Subtotal field.
Additional query words:
inf total
Keywords : kbusage kbdta FmsHowto
Version : WINDOWS:2000
Platform : WINDOWS
Issue type : kbhowto
|