Click here to monitor SSC
SQLServerCentral is supported by Red Gate Software Ltd.
 
Log in  ::  Register  ::  Not logged in
 
 
 
        
Home       Members    Calendar    Who's On


Add to briefcase ««1234»»»

Fun with Scale and Precision Expand / Collapse
Author
Message
Posted Friday, December 4, 2009 7:34 AM


SSCrazy

SSCrazySSCrazySSCrazySSCrazySSCrazySSCrazySSCrazySSCrazy

Group: General Forum Members
Last Login: Yesterday @ 6:24 AM
Points: 2,451, Visits: 2,342
Explanation is in the note.
Try to reduce the precision.
SELECT CAST(cast(1.67574 as decimal(38,10)) / cast(10000 as decimal(38,10)) AS DECIMAL(38,10) ) conv_factor
returns 0.0001670000
SELECT CAST(cast(1.67574 as decimal(29,10)) / cast(10000 as decimal(29,10)) AS DECIMAL(29,10) ) conv_factor
returns 0.0001675740
Post #828913
Posted Friday, December 4, 2009 7:44 AM
SSC Eights!

SSC Eights!SSC Eights!SSC Eights!SSC Eights!SSC Eights!SSC Eights!SSC Eights!SSC Eights!

Group: General Forum Members
Last Login: Tuesday, May 6, 2014 7:18 AM
Points: 989, Visits: 8,655
select cast(1.67574 as decimal(38,10)) = 1.675400000 which has precision 6 and scale 10, right?
and
select cast(10000 as decimal(38,10)) = 10000.0000000000 which has precision 1 and scale 10, right?

So,
p1 - s1 + s2 + max(6, s1 + p2 + 1) =
6 - 10 + 10 + max(6, 10 + 1 + 1) =
6 + 12 = 18.


And the result scale is max(6, s1 + p2 + 1) = max(6, 10 + 1 + 1) = 12.

So, where is the rounding happening?

In Dude76's step by step we see that d1 / d2 is being rounded and is not returning the promised 18 characters of precision and 12 positions of scale. Why?




Steve Eckhart
Post #828922
Posted Friday, December 4, 2009 8:00 AM
Ten Centuries

Ten CenturiesTen CenturiesTen CenturiesTen CenturiesTen CenturiesTen CenturiesTen CenturiesTen Centuries

Group: General Forum Members
Last Login: Today @ 4:55 PM
Points: 1,293, Visits: 1,645
vk-kirov (12/4/2009)
...
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


Well, if the result precision is 87, and the scale is 49, that's a potential of 49 to the right of the decimal point, leaving (87-49)=38 to the left. Now that's an interesting number. If the note were a hard-and-fast rule (i.e, preserve numbers to the left at all costs), the scale would have to be 0. My guess is that the equations aren't exactly as described in Technet. I expect SQL Server actually does the following process (equivalent to the equations except for cases where resulting precision needs to be reduced to 38):

(p1 = numerator precision, 
p2 = denominator precision,
pR = result precision;
equivalent s for scale)

-- min() ensures pR is no greater than 38 as mentioned in the note
-- in our example, it becomes 38
pR = min(p1-s1+s2+max(6,s1+p2+1),38)

-- by subtracting from pR and using max(), we ensure a minimum of 6 digits to the right
-- in our example this becomes max(38-(38-10+10),6) = max(0,6) = 6!
sR = max(pR-(p1-s1+s2),6)

If that's the case, the 6 digits simply comes from their choice of 6 as the minimum scale when precision has to be truncated.
Post #828945
Posted Friday, December 4, 2009 8:06 AM
Ten Centuries

Ten CenturiesTen CenturiesTen CenturiesTen CenturiesTen CenturiesTen CenturiesTen CenturiesTen Centuries

Group: General Forum Members
Last Login: Today @ 4:55 PM
Points: 1,293, Visits: 1,645
Steve Eckhart (12/4/2009)
select cast(1.67574 as decimal(38,10)) = 1.675400000 which has precision 6 and scale 10, right?
and
select cast(10000 as decimal(38,10)) = 10000.0000000000 which has precision 1 and scale 10, right?

wrong, and wrong. Because you're explicitly casting to decimal(38,10), both of your results have precision of 38 and scale of 10 even though they don't apparently require it. SQL server will not narrow the precision and scale of an explicitly cast decimal result.
Post #828955
Posted Friday, December 4, 2009 8:19 AM
SSC-Enthusiastic

SSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-Enthusiastic

Group: General Forum Members
Last Login: Friday, June 20, 2014 8:30 AM
Points: 129, Visits: 192
Nadabanan - thanks for spotting this. Have updated with correct text.
Post #828971
Posted Friday, December 4, 2009 8:28 AM
SSC Eights!

SSC Eights!SSC Eights!SSC Eights!SSC Eights!SSC Eights!SSC Eights!SSC Eights!SSC Eights!

Group: General Forum Members
Last Login: Tuesday, May 6, 2014 7:18 AM
Points: 989, Visits: 8,655
As someone stated earlier, the link apparently is incorrect since it doesn't enforce the minimum scale you describe here although we're obviously seeing it. I left feedback on the link that the information on division of decimals is incomplete and referenced this discussion.



Steve Eckhart
Post #828983
Posted Friday, December 4, 2009 11:05 AM
Old Hand

Old HandOld HandOld HandOld HandOld HandOld HandOld HandOld Hand

Group: General Forum Members
Last Login: Tuesday, January 1, 2013 3:03 PM
Points: 317, Visits: 1,018
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



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.
Post #829119
Posted Friday, December 4, 2009 11:10 AM
Forum Newbie

Forum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum Newbie

Group: General Forum Members
Last Login: Wednesday, November 20, 2013 1:29 AM
Points: 1, Visits: 8
So what we're really saying is that SS doesn't divide correctly.
sigh
Post #829122
Posted Tuesday, December 8, 2009 9:35 AM
SSCommitted

SSCommittedSSCommittedSSCommittedSSCommittedSSCommittedSSCommittedSSCommittedSSCommitted

Group: General Forum Members
Last Login: Friday, July 18, 2014 8:42 AM
Points: 1,706, Visits: 6,230
sknox (12/4/2009)
Steve Eckhart (12/4/2009)
select cast(1.67574 as decimal(38,10)) = 1.675400000 which has precision 6 and scale 10, right?
and
select cast(10000 as decimal(38,10)) = 10000.0000000000 which has precision 1 and scale 10, right?

wrong, and wrong. Because you're explicitly casting to decimal(38,10), both of your results have precision of 38 and scale of 10 even though they don't apparently require it. SQL server will not narrow the precision and scale of an explicitly cast decimal result.


I'm struggling here.
Surely that's exactly what SQLServer is doing?

Either way, the explanation attached to the QotD doesn't seem to attempt to explain it - and I'm not surprised!
Post #830797
Posted Tuesday, December 8, 2009 12:15 PM
Ten Centuries

Ten CenturiesTen CenturiesTen CenturiesTen CenturiesTen CenturiesTen CenturiesTen CenturiesTen Centuries

Group: General Forum Members
Last Login: Today @ 4:55 PM
Points: 1,293, Visits: 1,645
Toreador (12/8/2009)
sknox (12/4/2009)
Steve Eckhart (12/4/2009)
select cast(1.67574 as decimal(38,10)) = 1.675400000 which has precision 6 and scale 10, right?
and
select cast(10000 as decimal(38,10)) = 10000.0000000000 which has precision 1 and scale 10, right?

wrong, and wrong. Because you're explicitly casting to decimal(38,10), both of your results have precision of 38 and scale of 10 even though they don't apparently require it. SQL server will not narrow the precision and scale of an explicitly cast decimal result.


I'm struggling here.
Surely that's exactly what SQLServer is doing?


No. The equation in the QotD was:
CAST( cast(1.67574 as decimal(38,10)) / cast(10000 as decimal(38,10)) AS DECIMAL(38,10) )

Procedurally, this is what SQL Server does:
Step 1 is to cast 1.67574 as decimal(38, 10). This explicit cast is not narrowed, which is one reason why the calculation in (3) results in a result that has to be narrowed.

Step 2 is to cast 10000 as decimal(38, 10). This explicit cast is not narrowed, which is the other reason why the calculation in (3) results in a result that has to be narrowed.

Step 3 is to perform the division. This results in an answer whose precision and scale are beyond the ranges of the decimal data type. So the precision and scale are narrowed as discussed in this topic. Note that technically, this result is not explicitly cast.

Step 4 is to cast the final result (i.e, after the internal narrowing) as decimal(38,10). This explicit cast is also not narrowed, which is why we see the trailing 0s in the result.

An explicit cast that falls within the ranges of the decimal data type will not be narrowed. An explicit cast that falls outside the ranges of the decimal data type will result in an error. A calculation which results in precision and scale outside the ranges of the decimal data type will be narrowed to fit within those ranges as discussed.

I agree that the explanation on the QotD didn't explain it. That's why I did the research I did.
Post #830898
« Prev Topic | Next Topic »

Add to briefcase ««1234»»»

Permissions Expand / Collapse