When MySQL stores a value in a numeric column that is outside the permissible range of the column data type, the result depends on the SQL mode in effect at the time:
If strict SQL mode is enabled, MySQL rejects the out-of-range value with an error, and the insert fails, in accordance with the SQL standard.
If no restrictive modes are enabled, MySQL clips the value to the appropriate endpoint of the range and stores the resulting value instead.
When an out-of-range value is assigned to an integer column,
MySQL stores the value representing the corresponding
endpoint of the column data type range. If you store 256
into a TINYINT
or
TINYINT UNSIGNED
column, MySQL stores 127
or 255, respectively.
When a floating-point or fixed-point column is assigned a value that exceeds the range implied by the specified (or default) precision and scale, MySQL stores the value representing the corresponding endpoint of that range.
Column-assignment conversions that occur due to clipping when
MySQL is not operating in strict mode are reported as warnings
for ALTER TABLE
,
LOAD DATA
INFILE
, UPDATE
, and
multiple-row INSERT
statements.
In strict mode, these statements fail, and some or all the
values will not be inserted or changed, depending on whether the
table is a transactional table and other factors. For details,
see Section 5.1.7, “Server SQL Modes”.
In MySQL 5.1, overflow handling during numeric expression evaluation depends on the types of the operands:
Integer overflow results in silent wraparound.
DECIMAL
overflow results in a truncated
result and a warning.
Floating-point overflow produces a NULL
result. Before MySQL 5.1.24, overflow for some operations
results in +INF
, -INF
,
or NaN
.
For example, the largest signed
BIGINT
value is
9223372036854775807, so the following expression wraps around to
the minimum BIGINT
value:
mysql> SELECT 9223372036854775807 + 1;
+-------------------------+
| 9223372036854775807 + 1 |
+-------------------------+
| -9223372036854775808 |
+-------------------------+
To enable the operation to succeed in this case, convert the value to unsigned;
mysql> SELECT CAST(9223372036854775807 AS UNSIGNED) + 1;
+-------------------------------------------+
| CAST(9223372036854775807 AS UNSIGNED) + 1 |
+-------------------------------------------+
| 9223372036854775808 |
+-------------------------------------------+
Whether overflow occurs depends on the range of the operands, so
another way to handle the preceding expression is to use
exact-value arithmetic because
DECIMAL
values have a larger
range than integers:
mysql> SELECT 9223372036854775807.0 + 1;
+---------------------------+
| 9223372036854775807.0 + 1 |
+---------------------------+
| 9223372036854775808.0 |
+---------------------------+
Subtraction between integer values, where one is of type
UNSIGNED
, produces an unsigned result by
default. If the result would otherwise have been negative, it
becomes the maximum integer value. If the
NO_UNSIGNED_SUBTRACTION
SQL
mode is enabled, the result is negative.
mysql>SET sql_mode = '';
mysql>SELECT CAST(0 AS UNSIGNED) - 1;
+-------------------------+ | CAST(0 AS UNSIGNED) - 1 | +-------------------------+ | 18446744073709551615 | +-------------------------+ mysql>SET sql_mode = 'NO_UNSIGNED_SUBTRACTION';
mysql>SELECT CAST(0 AS UNSIGNED) - 1;
+-------------------------+ | CAST(0 AS UNSIGNED) - 1 | +-------------------------+ | -1 | +-------------------------+
If the result of such an operation is used to update an
UNSIGNED
integer column, the result is
clipped to the maximum value for the column type, or clipped to
0 if NO_UNSIGNED_SUBTRACTION
is enabled. If strict SQL mode is enabled, an error occurs and
the column remains unchanged.
User Comments
Add your own comment.