• wschampheleer (2/22/2010)


    The result of

    SELECT CAST(1.67574 AS DECIMAL(38,10)) / CAST(10000 AS DECIMAL(38,10)) conv_factor has datatype decimal(38,6).

    True.

    wschampheleer (2/22/2010)


    From BOL: In Transact-SQL statements, a constant with a decimal point is automatically converted into a numeric data value, using the minimum precision and scale necessary. For example, the constant 12.345 is converted into a numeric value with a precision of 5 and a scale of 3.

    Also true, but it does not explain what is going on here.

    It is true that the literal value 1.67574 would be implictly a DECIMAL(6,5). But, the CAST converts that explicitly to DECIMAL(38,10).

    A similar thing is true for the literal value 10000: implied DECIMAL(5,0). But, again, explicitly CAST to DECIMAL(38,10).

    So, we have two DECIMAL(38,10) values used with the division operator (/). What will be the scale and precision of the result?

    Well, in this case, both operands have the same base type (decimal) so we don't need to worry about type conversion.

    There is a formula for the precision and scale of this division result, contained in the reference at the end of this post.

    The formula applies to two expressions e1 and e2, with precision p1 and p2, and scale s1 and s2.

    In our case:

    p1 = 38

    p2 = 38

    s1 = 10

    s2 = 10

    The formula for the result precision is:

    (p1 - s1 + s2) + max(6, s1 + p2 + 1)

    = (10 - 38 + 38) + max(6, 38 + 10 + 1)

    = (10) + 49

    = 59

    The formula for the result scale is:

    max(6, s1 + p2 + 1)

    = max(6, 38 + 10 + 1)

    = 49

    (the imaginary max function here just returns the highest of the values passed to it)

    So, our result is a DECIMAL(59,49). That is a problem since SQL Server has a maximum precision of 38 (currently). Luckily, there is a rule for this scenario too:

    The result precision and scale have an absolute maximum of 38. When a result precision is greater than 38, the corresponding scale is reduced to prevent the integral part of a result from being truncated.

    It turns out that SQL Server never reduces the scale to less than 6 (the same magic number as in the max formulas before), and that is what happens here. There is no way divide one DECIMAL(38,10) by another and retain enough precision and scale for all valid values.

    SQL Server does not take account of the actual values stored in the expressions - it applies rules which produce predictable results depending only on the precision and scale of the inputs. It makes no difference therefore, that our expected result (0.000167574) would fit in a DECIMAL(10,10) - application of the rules for dividing a DECIMAL(38,10) by a DECIMAL(38,10) result in a DECIMAL(38,6) - the maximum value for precision, and the minimum value for scale.

    The essential point to take away from this is to never use a greater precision or scale than you have a sensible need for. If the original query had been this:

    SELECT CAST(1.67574 AS DECIMAL(6,5)) / CAST(10000 AS DECIMAL(5,0)) AS conv_factor

    ...the result would be 0.00016757400 - a DECIMAL(12,11).

    I'm not suggesting that only decimals of exactly the right size should ever be used - but consider storage size and the potential need for increased precision when arithmetic functions are performed.

    Paul


    Reference: Precision, Scale, and Length