SQL Clone
SQLServerCentral is supported by Redgate
 
Log in  ::  Register  ::  Not logged in
 
 
 


Two fields from two tables of same value not equal


Two fields from two tables of same value not equal

Author
Message
a2zwd
a2zwd
SSC-Enthusiastic
SSC-Enthusiastic (162 reputation)SSC-Enthusiastic (162 reputation)SSC-Enthusiastic (162 reputation)SSC-Enthusiastic (162 reputation)SSC-Enthusiastic (162 reputation)SSC-Enthusiastic (162 reputation)SSC-Enthusiastic (162 reputation)SSC-Enthusiastic (162 reputation)

Group: General Forum Members
Points: 162 Visits: 392
Hi,

I have 2 tables which has 2 float fields each.

I am joining these two tables and comparing two float fields whether they are equal or not.

Surprisingly, 2 fields with the same value returning not equal.

SELECT *
FROM Table1 t1
INNER JOIN @tab tmp
ON t1.CustomerNo = tmp.CustNo
WHERE cast(t1.TotalRevenue as float) <> tmp.CntRev

TotalRevenue and CntRev has the same value 33679.8 but above query returns rows(means values doesn't match)

How come?

Database collation is SQL_Latin1_General_CP1_CI_AI
Mike John
Mike John
SSCrazy
SSCrazy (2.9K reputation)SSCrazy (2.9K reputation)SSCrazy (2.9K reputation)SSCrazy (2.9K reputation)SSCrazy (2.9K reputation)SSCrazy (2.9K reputation)SSCrazy (2.9K reputation)SSCrazy (2.9K reputation)

Group: General Forum Members
Points: 2868 Visits: 5961
Float is not an exact data type. The internal storage format can mean rounding is being done that may not be visible to you. It would be interesting to get the exact internal value for both of these, just retrieve the varbinary conversion of them both and compare that. I expect you will see they are very slightly different.

As a general rule using float for monetary values is not a good idea, I would either use money (if the maths rules it uses are OK for you) or more likely numeric or decimal with an appropriate scale and precision for your needs.

Mike John



jonysuise
jonysuise
SSC-Enthusiastic
SSC-Enthusiastic (134 reputation)SSC-Enthusiastic (134 reputation)SSC-Enthusiastic (134 reputation)SSC-Enthusiastic (134 reputation)SSC-Enthusiastic (134 reputation)SSC-Enthusiastic (134 reputation)SSC-Enthusiastic (134 reputation)SSC-Enthusiastic (134 reputation)

Group: General Forum Members
Points: 134 Visits: 166
Float and real are approximate data types. Therefore you should use decimal.

Jonathan Bernardez Bernardez
___________________________________________________________
DBD. MCSA SQL Server 2012
L-P Larsson
L-P Larsson
Grasshopper
Grasshopper (20 reputation)Grasshopper (20 reputation)Grasshopper (20 reputation)Grasshopper (20 reputation)Grasshopper (20 reputation)Grasshopper (20 reputation)Grasshopper (20 reputation)Grasshopper (20 reputation)

Group: General Forum Members
Points: 20 Visits: 90
Float can have different precision: float(n) where 1 <= n <= 53. According to BOL, 1 <= n <= 23 is treated the same, and 24 <= n <= 53 the same. Is this maybe the cause, that the two columns are both float, but of different in precision?

Example: The second select clause will not return the row, the third will return the row:

create table #floats(f1 float(12) not null, f2 float(53) not null);
insert #floats values(PI(), PI());
select * from #floats;
select * from #floats where f1 = f2;
select * from #floats where f1 = Cast(f2 as float(12))
drop table #floats;


a2zwd
a2zwd
SSC-Enthusiastic
SSC-Enthusiastic (162 reputation)SSC-Enthusiastic (162 reputation)SSC-Enthusiastic (162 reputation)SSC-Enthusiastic (162 reputation)SSC-Enthusiastic (162 reputation)SSC-Enthusiastic (162 reputation)SSC-Enthusiastic (162 reputation)SSC-Enthusiastic (162 reputation)

Group: General Forum Members
Points: 162 Visits: 392
Hi all,

Thanks. CAST to decimal has worked.
Mike John
Mike John
SSCrazy
SSCrazy (2.9K reputation)SSCrazy (2.9K reputation)SSCrazy (2.9K reputation)SSCrazy (2.9K reputation)SSCrazy (2.9K reputation)SSCrazy (2.9K reputation)SSCrazy (2.9K reputation)SSCrazy (2.9K reputation)

Group: General Forum Members
Points: 2868 Visits: 5961
While cast to decimal may have worked in this instance, I think looking at the table definition and changing the underlying datatype there would be a better option - assuming you have the "power" to do so.

I appreciate it may be too hard/risky/politically impossible to do so.

Mike John



Tom Thomson
Tom Thomson
SSChampion
SSChampion (14K reputation)SSChampion (14K reputation)SSChampion (14K reputation)SSChampion (14K reputation)SSChampion (14K reputation)SSChampion (14K reputation)SSChampion (14K reputation)SSChampion (14K reputation)

Group: General Forum Members
Points: 14550 Visits: 12238
Mike John (10/18/2013)
Float is not an exact data type. The internal storage format can mean rounding is being done that may not be visible to you. It would be interesting to get the exact internal value for both of these, just retrieve the varbinary conversion of them both and compare that. I expect you will see they are very slightly different.

As a general rule using float for monetary values is not a good idea, I would either use money (if the maths rules it uses are OK for you) or more likely numeric or decimal with an appropriate scale and precision for your needs.

Mike John

Yes, the problem is most likely happening because FLOAT is not an exact numeric. And the solution (assuming exact numeric arithmetic is accurate enough - "exact" in the name refers to accuracy of representation of base 10 fractions, not to the accuracy of long chains of calculation) and has adequate range) would be to switch to using an exact numeric representation. If that isn't possible, just cast the numbers to an appropriate exact numeric type before comparing them and see if that works.

But the problem here may not be rounding; rounding in FLOAT generally introduces much smaller errors than rounding in exact numeric types (which usually throw away quite a lot of accuracy whenever they put the result of a computation into a field of predefined and precision). This doesn't make any difference to what the solution is, until we have a version of SQL that supports modern floating point standards. FLOAT does introduce a particular rounding error which decimal doesn't because SQL hasn't kept up with the recognised international standard on floating point, the representation error introduced by using a binary base for numbers which were expressed originally in base 10 - for example a quantity like 0.2 has no finite binary representation,so it's going to be rounded to something that does have a finite (53 bit, in the case of float) binary representation and that could be the source of the problem; but it's just as likely that the floating point arithmetic that calculated the numbers, because it doesn't introduce fairly large rounding errors every time it tores a value, has produced more accurate answers than exact numerics would and that the error is that the FLOAT rounding error is not big enough. Since the two values were calculated down different paths, the total rounding error will probbly be different in the two cases, which means the two answers will be different unless you round them to something a bit less accurate.

Tom

Go


Permissions

You can't post new topics.
You can't post topic replies.
You can't post new polls.
You can't post replies to polls.
You can't edit your own topics.
You can't delete your own topics.
You can't edit other topics.
You can't delete other topics.
You can't edit your own posts.
You can't edit other posts.
You can't delete your own posts.
You can't delete other posts.
You can't post events.
You can't edit your own events.
You can't edit other events.
You can't delete your own events.
You can't delete other events.
You can't send private messages.
You can't send emails.
You can read topics.
You can't vote in polls.
You can't upload attachments.
You can download attachments.
You can't post HTML code.
You can't edit HTML code.
You can't post IFCode.
You can't post JavaScript.
You can post emoticons.
You can't post or upload images.

Select a forum

































































































































































SQLServerCentral


Search