Bug #46037 Inconsistent behavior when casting floating point numbers to integer
Submitted: 8 Jul 2009 11:11 Modified: 8 Jul 2009 12:28
Reporter: Øystein Grøvlen Email Updates:
Status: Verified Impact on me:
None 
Category:MySQL Server: Data Types Severity:S3 (Non-critical)
Version:mysql-azalea/5.1 OS:Any
Assigned to: Assigned Account CPU Architecture:Any

[8 Jul 2009 11:11] Øystein Grøvlen
Description:
If I try to cast float/double columns to signed/unsigned integers the
result is not very consistent:

mysql> create table t1(f float, d double);
Query OK, 0 rows affected (0.01 sec)

mysql> select cast(f as signed int), cast(f as unsigned int), cast(d as signed int), cast(d as unsigned int) from t1;
+-----------------------+-------------------------+-----------------------+-------------------------+
| cast(f as signed int) | cast(f as unsigned int) | cast(d as signed int) | cast(d as unsigned int) |
+-----------------------+-------------------------+-----------------------+-------------------------+
|  -9223372036854775808 |     9223372036854775808 |  -9223372036854775808 | 9223372036854775808 |
|  -9223372036854775808 |     9223372036854775808 |   9223372036854775807 | 9223372036854775807 |
+-----------------------+-------------------------+-----------------------+-------------------------+
2 rows in set, 4 warnings (0.00 sec)

NOTE: Only four truncation warnings, would expect eight (one for each value):

mysql> show warnings;
+---------+------+--------------------------------------------+
| Level   | Code | Message                                    |
+---------+------+--------------------------------------------+
| Warning | 1292 | Truncated incorrect INTEGER value: '-1e30' |
| Warning | 1292 | Truncated incorrect INTEGER value: '-1e30' |
| Warning | 1292 | Truncated incorrect INTEGER value: '1e30'  |
| Warning | 1292 | Truncated incorrect INTEGER value: '1e30'  |
+---------+------+--------------------------------------------+
4 rows in set (0.00 sec)

NOTE: If inserting float/decimal into an integer column, result is a bit different:

mysql> create table t2(i bigint, u bigint unsigned);
Query OK, 0 rows affected (0.00 sec)

mysql> insert into t2 select f, f from t1;
Query OK, 2 rows affected, 4 warnings (0.00 sec)
Records: 2  Duplicates: 0  Warnings: 4

mysql> insert into t2 select d, d from t1;
Query OK, 2 rows affected, 4 warnings (0.00 sec)
Records: 2  Duplicates: 0  Warnings: 4

mysql> select * from t2;
+----------------------+----------------------+
| i                    | u                    |
+----------------------+----------------------+
| -9223372036854775808 |                    0 |
|  9223372036854775807 | 18446744073709551615 |
| -9223372036854775808 |                    0 |
|  9223372036854775807 | 18446744073709551615 |
+----------------------+----------------------+
4 rows in set (0.00 sec)

How to repeat:
create table t1(f float, d double);
insert into t1 values (-1e30,-1e30), (1e30,1e30);
select cast(f as signed int), cast(f as unsigned int), cast(d as signed int), cast(d as unsigned int) from t1;
create table t2(i bigint, u bigint unsigned);
insert into t2 select f, f from t1;
insert into t2 select d, d from t1;
select * from t2;
[8 Jul 2009 12:28] MySQL Verification Team
Thank you for the bug report. Verified as described.
[8 Jul 2009 13:53] MySQL Verification Team
5.1 presented same behavior and 5.0 a different error message:

c:\dbs>c:\dbs\5.0\bin\mysql -uroot --port=3500 --prompt="mysql 5.0 > "
Welcome to the MySQL monitor.  Commands end with ; or \g.
Your MySQL connection id is 1
Server version: 5.0.83-Win X64-log Source distribution

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

mysql 5.0 > create database r2;
Query OK, 1 row affected (0.01 sec)

mysql 5.0 > use r2
Database changed
mysql 5.0 > create table t1(f float, d double);
Query OK, 0 rows affected (0.12 sec)

mysql 5.0 > insert into t1 values (-1e30,-1e30), (1e30,1e30);
Query OK, 2 rows affected (0.00 sec)
Records: 2  Duplicates: 0  Warnings: 0

mysql 5.0 > select cast(f as signed int), cast(f as unsigned int), cast(d as signed int), cast(d as
    -> unsigned int) from t1;
+-----------------------+-------------------------+-----------------------+-------------------------+
| cast(f as signed int) | cast(f as unsigned int) | cast(d as signed int) | cast(d as
unsigned int) |
+-----------------------+-------------------------+-----------------------+-------------------------+
|  -9223372036854775808 |     9223372036854775808 |  -9223372036854775808 |     9223372036854775808 |
|  -9223372036854775808 |     9223372036854775808 |   9223372036854775807 |     9223372036854775807 |
+-----------------------+-------------------------+-----------------------+-------------------------+
2 rows in set, 4 warnings (0.00 sec)

mysql 5.0 > create table t2(i bigint, u bigint unsigned);
Query OK, 0 rows affected (0.12 sec)

mysql 5.0 > insert into t2 select f, f from t1;
ERROR 1264 (22003): Out of range value adjusted for column 'i' at row 1
mysql 5.0 > insert into t2 select d, d from t1;
ERROR 1264 (22003): Out of range value adjusted for column 'i' at row 1
mysql 5.0 > select * from t2;
Empty set (0.00 sec)
[16 Jul 2009 14:11] Øystein Grøvlen
This should be fixed by the work on Value object (WL#4904)