ACC: DSum Causes Rounding Error on Large Currency Fields (95/97)ID: Q177360
|
Moderate: Requires basic macro, coding, and interoperability skills.
Using the domain aggregate (totals) function DSum() to total a currency
field may cause rounding errors for values exceeding fourteen significant
digits. The same behavior occurs when you use the aggregate Sum() function.
This article assumes that you are familiar with Visual Basic for
Applications and with creating Microsoft Access applications using the
programming tools provided with Microsoft Access. For more information
about Visual Basic for Applications, please refer to your version of the
"Building Applications with Microsoft Access" manual.
If you use the Currency data type, rounding errors typically do not occur because Currency values are scaled integers rather than floating point numbers. However, the Sum() and DSum() functions store an accumulated total as a floating point number, which is limited to approximately 14 significant digits. If you require all 19 digits of precision (15 to the left of the decimal point and 4 to the right of the decimal point), you can use a custom domain aggregate function. You should use the built-in Sum() and DSum() functions if you do not require this degree of precision.
Function DCurSum(Expr As String, Domain As String, _
Optional Criteria As Variant) As Variant
On Error GoTo Err_DCurSum
Dim rst As Recordset, curTotal As Currency, fld As Field
Dim db As Database, strSQL As String
Set db = CurrentDb
If IsMissing(Criteria) Then ' No criteria provided.
strSQL = "Select " & Expr & " AS DCurSumExpr From " & _
Domain & ";"
Else ' Add criteria to SQL statement.
strSQL = "Select " & Expr & " AS DCurSumExpr From " & _
Domain & " WHERE " & Criteria & ";"
End If
Set rst = db.OpenRecordset(strSQL, dbOpenSnapshot)
curTotal = 0
Do Until rst.EOF ' Loop through all the records.
If IsNumeric(rst("DCurSumExpr")) Then _
curTotal = curTotal + rst("DCurSumExpr") ' Add the numbers.
rst.MoveNext
Loop
DCurSum = CCur(curTotal)
Exit_DCurSum:
Exit Function
Err_DCurSum:
DCurSum = "#Error"
Resume Exit_DCurSum
End Function
Table: tblCurrencySum
------------------------
Field Name: CurrencyTest
Data Type: Currency
$123,456,789,012,345.67
($123,456,789,012,345.66)
For more information about custom domain functions, please see the
following articles in the Microsoft Knowledge Base:
Q103401 ACC:How to Create Custom Domain Function Similar to DCount()
Q146415 ACC: Creating Functions Similar to DFirst and DLast (95/97)
For more information about rounding errors, please see the following
articles in the Microsoft Knowledge Base:
Q111781 ACC: Rounding Errors Using Floating-Point Numbers
Q35826 IEEE vs. Microsoft Binary Format; Rounding Issues (Complete)
Additional query words: prb incorrect wrong rounding rounded incorrectly off
Keywords : SynFnc
Version : WINDOWS:7.0,97
Platform : WINDOWS
Issue type : kbprb
Last Reviewed: April 26, 1999