PRB: Loss of Precision May Occur When You Use SUM or AVG Functions In a Formula with Division (281341)
The information in this article applies to:
- Microsoft SQL Server 7.0
- Microsoft SQL Server 2000 (all editions)
This article was previously published under Q281341 SYMPTOMS
When you use the SUM or AVG aggregate function with division, the result loses precision. The loss of precision occurs regardless of whether you use a numeric or decimal datatype.
CAUSE
This behavior is due to the nature of decimal and numeric datatypes and the truncation that occurs as a result of the precision and the scale values. According to SQL Server Books Online, the result of sum(numeric(p,s)) is numeric(38,s). In the preceding case, sum(amount) is numeric(38,9). When you have an expression of numeric(38,9) / numeric(15,9); ideally, the result is numeric(63,25). However, because the maximum precision is 38, the result truncates to (38,6).
WORKAROUND
To work around this behavior, use either of these methods:
- Use a numeric as the divisor. For example:
DECLARE @Quantity numeric(15,9)
SET @Quantity = 3
SELECT Round(CAST(Sum(t1.Amount) AS numeric(15,9))/@Quantity, 9) As Cost
FROM t1
- Store the sum in a variable first, and use the variable in the formula. For example:
declare @quantity numeric (15,9)
set @quantity = 3
declare @sum numeric (15,9)
set @sum= (select sum(amount) from t1)
select @sum/@quantity as cost
- Put an explicit value in a denominator. For example:
select sum(Amount)/3 from t1
Modification Type: | Major | Last Reviewed: | 10/16/2003 |
---|
Keywords: | kbprb KB281341 |
---|
|