March 1, 2010 at 12:56 pm
I have two tables that are the same - except each one is updated by their own ETL process of which one has been heavily revised - so this is a parallel run.
"Table1" and "PARALLEL_Table1" have a column called TotValue of type FLOAT. On both tables the value in the column for the same row is 49.395 (no other decimal places).
When I run the query:
select convert(decimal(28,2),TotValue) as TotValue
from Table1
where id = 123456
union all
select convert(decimal(28,2),TotValue) as TotValue
from PARALLEL_Table1
where id = 123456
The result set is:
49.39
49.40
This is happening all over the place with one penny of difference in each case. If I change decimal(28,2) to decimal(28,3) then the problem goes away. But I need to understand why the rounding is inconsistent to help me narrow down the differences between the two tables quickly. Can anyone explain these differences? Thanks in advance! 🙂
March 1, 2010 at 1:32 pm
FLOAT is an imprecise data type...
try this:
declare @val float
select @val=49.395
select @val,convert(decimal(38,28),@val)
and notice that @val does not exactly equal 49.395
then try
select convert(decimal(38,28),TotValue) as TotValue
from Table1
where id = 123456
union all
select convert(decimal(38,28),TotValue) as TotValue
from PARALLEL_Table1
where id = 123456
and you will no doubt see that one of the values is actually slightly less than 49.395 and one is slightly more, this variance will show itself as different rounding.
MM
select geometry::STGeomFromWKB(0x0106000000020000000103000000010000000B0000001000000000000840000000000000003DD8CCCCCCCCCC0840000000000000003DD8CCCCCCCCCC08408014AE47E17AFC3F040000000000104000CDCCCCCCCCEC3F9C999999999913408014AE47E17AFC3F9C99999999991340000000000000003D0000000000001440000000000000003D000000000000144000000000000000400400000000001040000000000000F03F100000000000084000000000000000401000000000000840000000000000003D0103000000010000000B000000000000000000143D000000000000003D009E99999999B93F000000000000003D009E99999999B93F8014AE47E17AFC3F400000000000F03F00CDCCCCCCCCEC3FA06666666666FE3F8014AE47E17AFC3FA06666666666FE3F000000000000003D1800000000000040000000000000003D18000000000000400000000000000040400000000000F03F000000000000F03F000000000000143D0000000000000040000000000000143D000000000000003D, 0);
March 1, 2010 at 2:30 pm
Thanks Mr Magoo - I'll try what you suggest at work tmw.:-)
March 2, 2010 at 12:16 pm
After much experimentation, it seems that a method that works quite well to round two slightly different FLOAT numbers like:
41.4750000000000000
41.4749999999999999
is to round firstly to one decimal place (1dp) more than you need and then to the dp that you actually need. Therefore the code for the above would be:
round(round(TotPaid,3),2).
Both numbers above yield 41.48 with this rounding approach which means they can be reconciled. Also, the binary_checksum function will return the same number which doesn't happen with the example two numbers in the standard FLOAT format. I use the binary_checksum function to reconcile rows on two similar tables that are parallel running.:-)
March 2, 2010 at 12:39 pm
Another approach I sometimes use is to compare like this:
SELECT ....
WHERE ABS(float_1 - float_2)>=0.01
Changing the 0.01 to whatever value you consider to be a variance.
MM
select geometry::STGeomFromWKB(0x0106000000020000000103000000010000000B0000001000000000000840000000000000003DD8CCCCCCCCCC0840000000000000003DD8CCCCCCCCCC08408014AE47E17AFC3F040000000000104000CDCCCCCCCCEC3F9C999999999913408014AE47E17AFC3F9C99999999991340000000000000003D0000000000001440000000000000003D000000000000144000000000000000400400000000001040000000000000F03F100000000000084000000000000000401000000000000840000000000000003D0103000000010000000B000000000000000000143D000000000000003D009E99999999B93F000000000000003D009E99999999B93F8014AE47E17AFC3F400000000000F03F00CDCCCCCCCCEC3FA06666666666FE3F8014AE47E17AFC3FA06666666666FE3F000000000000003D1800000000000040000000000000003D18000000000000400000000000000040400000000000F03F000000000000F03F000000000000143D0000000000000040000000000000143D000000000000003D, 0);
Viewing 5 posts - 1 through 4 (of 4 total)
You must be logged in to reply to this topic. Login to reply