Floating-point numbers sometimes cause confusion because they
are approximate and not stored as exact values. A
floating-point value as written in an SQL statement may not be
the same as the value represented internally. Attempts to
treat floating-point values as exact in comparisons may lead
to problems. They are also subject to platform or
implementation dependencies. The
FLOAT
and
DOUBLE
data types are subject
to these issues. For DECIMAL
columns, MySQL performs operations with a precision of 65
decimal digits, which should solve most common inaccuracy
problems.
The following example uses
DOUBLE
to demonstrate how
calculations that are done using floating-point operations are
subject to floating-point error.
mysql> CREATE TABLE t1 (i INT, d1 DOUBLE, d2 DOUBLE);
mysql> INSERT INTO t1 VALUES (1, 101.40, 21.40), (1, -80.00, 0.00),
-> (2, 0.00, 0.00), (2, -13.20, 0.00), (2, 59.60, 46.40),
-> (2, 30.40, 30.40), (3, 37.00, 7.40), (3, -29.60, 0.00),
-> (4, 60.00, 15.40), (4, -10.60, 0.00), (4, -34.00, 0.00),
-> (5, 33.00, 0.00), (5, -25.80, 0.00), (5, 0.00, 7.20),
-> (6, 0.00, 0.00), (6, -51.40, 0.00);
mysql> SELECT i, SUM(d1) AS a, SUM(d2) AS b
-> FROM t1 GROUP BY i HAVING a <> b;
+------+-------+------+
| i | a | b |
+------+-------+------+
| 1 | 21.4 | 21.4 |
| 2 | 76.8 | 76.8 |
| 3 | 7.4 | 7.4 |
| 4 | 15.4 | 15.4 |
| 5 | 7.2 | 7.2 |
| 6 | -51.4 | 0 |
+------+-------+------+
The result is correct. Although the first five records look
like they should not satisfy the comparison (the values of
a
and b
do not appear to
be different), they may do so because the difference between
the numbers shows up around the tenth decimal or so, depending
on factors such as computer architecture or the compiler
version or optimization level. For example, different CPUs may
evaluate floating-point numbers differently.
If columns d1
and d2
had
been defined as DECIMAL
rather
than DOUBLE
, the result of the
SELECT
query would have
contained only one row—the last one shown above.
The correct way to do floating-point number comparison is to first decide on an acceptable tolerance for differences between the numbers and then do the comparison against the tolerance value. For example, if we agree that floating-point numbers should be regarded the same if they are same within a precision of one in ten thousand (0.0001), the comparison should be written to find differences larger than the tolerance value:
mysql> SELECT i, SUM(d1) AS a, SUM(d2) AS b FROM t1
-> GROUP BY i HAVING ABS(a - b) > 0.0001;
+------+-------+------+
| i | a | b |
+------+-------+------+
| 6 | -51.4 | 0 |
+------+-------+------+
1 row in set (0.00 sec)
Conversely, to get rows where the numbers are the same, the test should find differences within the tolerance value:
mysql> SELECT i, SUM(d1) AS a, SUM(d2) AS b FROM t1
-> GROUP BY i HAVING ABS(a - b) <= 0.0001;
+------+------+------+
| i | a | b |
+------+------+------+
| 1 | 21.4 | 21.4 |
| 2 | 76.8 | 76.8 |
| 3 | 7.4 | 7.4 |
| 4 | 15.4 | 15.4 |
| 5 | 7.2 | 7.2 |
+------+------+------+
5 rows in set (0.03 sec)
Floating-point values are subject to platform or implementation dependencies. Suppose that you execute the following statements:
CREATE TABLE t1(c1 FLOAT(53,0), c2 FLOAT(53,0));
INSERT INTO t1 VALUES('1e+52','-1e+52');
SELECT * FROM t1;
On some platforms, the SELECT
statement
returns inf
and -inf
. On
others, it returns 0
and
-0
.
An implication of the preceding issues is that if you attempt to create a replica by dumping table contents with mysqldump on the source and reloading the dump file into the replica, tables containing floating-point columns might differ between the two hosts.