• vk-kirov (12/4/2009)


    stewartc-708166 (12/3/2009)


    the explanation re why the rounding off takes place is.....?

    Something about this can be found in BOL, topic "Precision, Scale, and Length (Transact-SQL)": http://technet.microsoft.com/en-us/library/ms190476.aspx

    We have two numbers of type NUMERIC(38,10), so their precision = 38 and scale = 10.

    According to the table from the above link, the result precision is: p1 - s1 + s2 + max(6, s1 + p2 + 1) = 38 - 10 + 10 + max(6, 10 + 38 + 1) = 38 + 49 = 87.

    The result scale is: max(6, s1 + p2 + 1) = max(6, 10 + 38 + 1) = 49.

    But there is also a note:

    * 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.

    Ok, the result precision (87) is definitely greater than 38, so it was reduced to 38. But why the scale was reduced to 6 – I can't find any explanation :ermm:

    The ResultingPrecision = 87 and ResultingScale = 49. However, the ResultingPrecision has to be reduced since it is greater than 38. To get to 38, we substract 87 by 49. Since we reduced ResultingPrecision by 49, we need to reduce the ResultingScale by 49 as well. (49 - 49) leaves us a ResultingScale of 0. However max(6, 0) = 6, so the ResultingScale ends up as 6. Therefore, result is truncated ( not rounded ) to 6 decimal digits.

    So.

    SELECT cast(1.67574 as decimal(38,10)) / cast(10000 as decimal(38,10))

    gives us 0.000167 -> precision of 38 and scale of 6

    so

    SELECT CAST( cast(1.67574 as decimal(38,10)) / cast(10000 as decimal(38,10)) AS DECIMAL(38,10) ) conv_factor

    reduces to

    SELECT CAST( 0.000167 AS DECIMAL(38,10) ) conv_factor

    which gives us 0.0001670000.

    Took me a while to figure this out. The real question is why SELECT cast(1.67574 as decimal(38,10)) / cast(10000 as decimal(38,10)) gives us 0.000167. The outer CAST is just a silly distraction.