PRB: Loss of Precision May Occur When You Use SUM or AVG Functions In a Formula with Division

This article was previously published under Q281341
This article has been archived. It is offered "as is" and will no longer be updated.
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 = 3SELECT Round(CAST(Sum(t1.Amount) AS numeric(15,9))/@Quantity, 9) As CostFROM t1					
  • Store the sum in a variable first, and use the variable in the formula. For example:

    declare @quantity numeric (15,9)set @quantity = 3declare @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					
MORE INFORMATION
To reproduce the behavior, run the following query from Query Analyzer:
CREATE TABLE t1 (    Amount    numeric(15,9)    )GOINSERT INTO t1( Amount ) VALUES (0.7)INSERT INTO t1( Amount ) VALUES (1.3)SELECT Amount FROM t1/* result (correct, scale = 9)Amount      ----------------- .7000000001.300000000DECLARE @Quantity numeric(15,9)SET @Quantity = 3    SELECT t1.Amount / @Quantity As CostFROM t1				
Again, the scale and precision are correct in the result.

However, if you use this code
DECLARE @Quantity numeric(15,9)<BR/>SET @Quantity = 3SELECT Sum(t1.Amount)/@Quantity As Cost<BR/>FROM t1				
the result is .666666.

The loss of precision does not occur if you provide an explicit value in the denominator. Loss of precision does not occur if you put in the value of the sum:
select sum(Amount)/3 from t1GOselect 2.0000000/@quantity				
No loss of precision occurs if you store SUM(amount) in a variable and you then use the variable. The loss of precision only occurs when you use the aggregate keyword SUM or AVG in a mathematical formula with division.
declare @quantity numeric (15,9)set @quantity = 3declare @sum numeric (15,9)set @sum= (select sum(amount) from t1)select @sum/@quantity as cost				
precision SUM AVG truncation division
Properties

Article ID: 281341 - Last Review: 12/05/2015 23:03:32 - Revision: 3.2

Microsoft SQL Server 7.0 Standard Edition, Microsoft SQL Server 2000 Standard Edition

  • kbnosurvey kbarchive kbprb KB281341
Feedback