ACC2000: Sample Function to Create a Running Sum on a FormID: q210338
|
This article shows you how to create a sample user-defined function to compute a running sum on a form.
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 FormUsing the method demonstrated in this article has the following advantages over using the DSum() function:
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/refguide/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.
Option Explicit
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
Query: qryOrders
------------------------------------------------------
Type: select query
Join: Orders.[OrderID] <->; [Order Subtotals].[OrderID]
Field: OrderID
Table: Orders
Sort: Ascending
Field: Subtotal
Table: Order Subtotals
Name: RunningSum
ControlSource: =RunSum([Form],"OrderID",[OrderID],"Subtotal")
Format: Currency
Additional query words: inf total
Keywords : kbusage kbdta FmsHowto
Version : WINDOWS:2000
Platform : WINDOWS
Issue type : kbhowto
Last Reviewed: May 28, 1999