September 27, 2012 at 10:23 am
If I run the following on SQL Server 2012 I get two different answers from the first two select statments.
Any reason why and what I need to do to avoid this. The second statement gives the wrong answer and that is the statement that I need to use in my code. With the change in statement 3 , I get the right answer but I am not getting the confidence that I should introduce the change in all my calculations.
select round((1400.05 / 4232.33 ) * 4180.06 ,2) --Statement 1
declare @v1 smallmoney = 1400.05,
@v2 smallmoney = 4232.33,
@v3 smallmoney = 4180.06
select round((@v1 / @v2 ) * @v3 ,2) --Statement 2
select round((@v1*1.0 / @v2 ) * @v3 ,2) --Statement 3
Thank you very much for the help.
Regards
Divesh
September 27, 2012 at 10:40 am
I think the intermediate result from @v1 / @v2 is being truncated because you're using smallmoney data type.
Can you use a different datatype, or cast one value to decimal to make it clearer what's happening.
e.g.
select round((CAST(@v1 as decimal(18,2)) / @v2 ) * @v3 ,2) --Statement 2
or
declare @v1 smallmoney = 1400.05,
@v2 smallmoney = 4232.33,
@v3 smallmoney = 4180.06
select round((CAST(@v1 as decimal(18,2)) / @v2 ) * @v3 ,2), --Statement 2
CAST(@v1 as decimal(18,2)) / @v2,
CAST(round((CAST(@v1 as decimal(18,2)) / @v2 ) * @v3 ,2) as SmallMoney) -- <----<<<
September 27, 2012 at 10:55 am
Laurie,
Thank you for your reply.
I guess if I force a cast to a decimal it will work since that is what happens when I add the "* 1.0" but I thought money or smallmoney was a decimal number.
Even if I change the datatype to money, I get the same results.
If we have to force a cast or conversion to a decimal type then does it mean that there is no point in using the money or smallmoney data type? !!! I hope this is not the conclusion of this. 🙂
Thanks for any more leads on this.
Regards
Divesh
September 27, 2012 at 11:05 am
Money & Smallmoney both have 4 decimal places, so that's why they lose the detail. If you're looking for accuracy it's better to use decimal.
It's all a bit of a minefield.:hehe:
September 27, 2012 at 11:13 am
September 27, 2012 at 11:34 am
diveshps (9/27/2012)
Laurie,Thank you for your reply.
I guess if I force a cast to a decimal it will work since that is what happens when I add the "* 1.0" but I thought money or smallmoney was a decimal number.
Even if I change the datatype to money, I get the same results.
If we have to force a cast or conversion to a decimal type then does it mean that there is no point in using the money or smallmoney data type? !!! I hope this is not the conclusion of this. 🙂
Thanks for any more leads on this.
Regards
Divesh
Speaking for myself, I always use DECIMAL to store dollar amounts to avoid exactly this sort of issue. I've never seen the point of money or smallmoney.
September 27, 2012 at 12:21 pm
cphite (9/27/2012)
Speaking for myself, I always use DECIMAL to store dollar amounts to avoid exactly this sort of issue. I've never seen the point of money or smallmoney.
Backwards compatibility.
Never stop learning, even if it hurts. Ego bruises are practically mandatory as you learn unless you've never risked enough to make a mistake.
For better assistance in answering your questions[/url] | Forum Netiquette
For index/tuning help, follow these directions.[/url] |Tally Tables[/url]
Twitter: @AnyWayDBA
March 6, 2013 at 3:42 am
This behaviour is due to data type precedence.
(@v1 / @v2 ) * @v3 will return smallmoney
((@v1 * 1.0) / @v2 ) * @v3 will return numeric
This can be demonstrated like this:
DECLARE @v1 SMALLMONEY = 1400.05,
@v2 SMALLMONEY = 4232.33;
SELECT @v1 / @v2 AS Val INTO TestTable1
SELECT @v1 / @v2 * 1.0 AS Val INTO TestTable2
EXEC sp_help TestTable1
EXEC sp_help TestTable2
DROP TABLE TestTable1
DROP TABLE TestTable2
And you will see the following:
TestTable1
Name - Val
Type - smallmoney
Length - 4
Precision - 10
Scale - 4
TestTable 2
Name - Val
Type - numeric
Length - 9
Precision - 13
Scale - 5
March 6, 2013 at 5:12 pm
YOu may folow the money :hehe: by tracing intermediate results:
select (1400.05 / 4232.33 ), (1400.05 / 4232.33 ) * 4180.06, round((1400.05 / 4232.33 ) * 4180.06 ,2) --Statement 1
declare @v1 smallmoney = 1400.05,
@v2 smallmoney = 4232.33,
@v3 smallmoney = 4180.06
select @v1, (@v1 / @v2 ), (@v1 / @v2 ) * @v3, round((@v1 / @v2 ) * @v3 ,2) --Statement 2
select @v1*1.0, (@v1*1.0 / @v2 ) ,(@v1*1.0 / @v2 ) * @v3 , round((@v1*1.0 / @v2 ) * @v3 ,2) --Statement 3
For most accurate calculations always use FLOAT data type (unless you need to handle more than 15 digigts, than use "big" decimals).
Try use FLOAT in your example and you'll see that 4 digit returned by DECIMAL calculation is incorrect.
Fortunateluy for you, it's beyond rounding precision.
_____________
Code for TallyGenerator
Viewing 9 posts - 1 through 8 (of 8 total)
You must be logged in to reply to this topic. Login to reply