Bug #72056 Wrong comparsion on big DECIMAL values
Submitted: 17 Mar 2014 10:19 Modified: 21 May 2015 0:51
Reporter: Artem Zaytsev Email Updates:
Status: Closed Impact on me:
None 
Category:MySQL Server: DML Severity:S1 (Critical)
Version:5.5/5.6 OS:Linux
Assigned to: Tor Didriksen CPU Architecture:Any
Tags: decimal

[17 Mar 2014 10:19] Artem Zaytsev
Description:
Comparison works differently for the search by index and without index

How to repeat:
mysql> CREATE TABLE `decimalTest`(`value` DECIMAL(24,0) NOT NULL);
Query OK, 0 rows affected (0.01 sec)

mysql> INSERT INTO `decimalTest`(`value`) VALUES('100000000000000000000001'), ('100000000000000000000002'), ('100000000000000000000003');
Query OK, 3 rows affected (0.00 sec)
Records: 3  Duplicates: 0  Warnings: 0

mysql> SELECT * FROM `decimalTest` WHERE `value` = '100000000000000000000002';
+--------------------------+
| value                    |
+--------------------------+
| 100000000000000000000001 |
| 100000000000000000000002 |
| 100000000000000000000003 |
+--------------------------+
3 rows in set (0.00 sec)

mysql> SELECT * FROM `decimalTest` WHERE `value` = 100000000000000000000002;
+--------------------------+
| value                    |
+--------------------------+
| 100000000000000000000002 |
+--------------------------+
1 row in set (0.00 sec)

mysql> ALTER TABLE `decimalTest` ADD INDEX `value` (`value`);
Query OK, 0 rows affected (0.01 sec)
Records: 0  Duplicates: 0  Warnings: 0

mysql> SELECT * FROM `decimalTest` WHERE `value` = '100000000000000000000002';
+--------------------------+
| value                    |
+--------------------------+
| 100000000000000000000002 |
+--------------------------+
1 row in set (0.00 sec)

mysql> SELECT * FROM `decimalTest` WHERE `value` = 100000000000000000000002;
+--------------------------+
| value                    |
+--------------------------+
| 100000000000000000000002 |
+--------------------------+
1 row in set (0.00 sec)

mysql>
[17 Mar 2014 11:30] MySQL Verification Team
Thank you for the bug report.

C:\dbs>c:\dbs\5.6\bin\mysql -uroot --port=3560 --prompt="mysql 5.6 > "
Welcome to the MySQL monitor.  Commands end with ; or \g.
Your MySQL connection id is 1
Server version: 5.6.17 Source distribution

Copyright (c) 2000, 2014, Oracle and/or its affiliates. All rights reserved.

Oracle is a registered trademark of Oracle Corporation and/or its
affiliates. Other names may be trademarks of their respective
owners.

Type 'help;' or '\h' for help. Type '\c' to clear the current input statement.

mysql 5.6 > use test
Database changed
mysql 5.6 > CREATE TABLE `decimalTest`(`value` DECIMAL(24,0) NOT NULL);
Query OK, 0 rows affected (0.42 sec)

mysql 5.6 >  INSERT INTO `decimalTest`(`value`) VALUES('100000000000000000000001'), ('100000000000000000000002'), ('100000000000000000000003');
Query OK, 3 rows affected (0.09 sec)
Records: 3  Duplicates: 0  Warnings: 0

mysql 5.6 > SELECT * FROM `decimalTest` WHERE `value` = '100000000000000000000002';
+--------------------------+
| value                    |
+--------------------------+
| 100000000000000000000001 |
| 100000000000000000000002 |
| 100000000000000000000003 |
+--------------------------+
3 rows in set (0.06 sec)

mysql 5.6 > SELECT * FROM `decimalTest` WHERE `value` = 100000000000000000000002;
+--------------------------+
| value                    |
+--------------------------+
| 100000000000000000000002 |
+--------------------------+
1 row in set (0.03 sec)

mysql 5.6 > ALTER TABLE `decimalTest` ADD INDEX `value` (`value`);
Query OK, 0 rows affected (0.37 sec)
Records: 0  Duplicates: 0  Warnings: 0

mysql 5.6 > SELECT * FROM `decimalTest` WHERE `value` = '100000000000000000000002';
+--------------------------+
| value                    |
+--------------------------+
| 100000000000000000000002 |
+--------------------------+
1 row in set (0.02 sec)

mysql 5.6 > SELECT * FROM `decimalTest` WHERE `value` = 100000000000000000000002;
+--------------------------+
| value                    |
+--------------------------+
| 100000000000000000000002 |
+--------------------------+
1 row in set (0.00 sec)

mysql 5.6 >
[28 Mar 2014 15:56] Tor Didriksen
Unfortunately, this result is according to our documentation:
http://dev.mysql.com/doc/refman/5.6/en/type-conversion.html
"In all other cases, the arguments are compared as floating-point (real) numbers."

The quoted literal is treated as a string, and 100000000000000000000002
has more than DBL_DIG == 15 digits, so floating-point comparison treats
them as equal.
[21 May 2015 0:51] Paul DuBois
Noted in 5.7.8, 5.8.0 changelogs.

Large integer literals converted to floats for comparison with
decimal data could lose precision and produce incorrect results.