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 column data type 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. - 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. 
        Suppose that a table t1 has this definition:
      
CREATE TABLE t1 (i1 TINYINT, i2 TINYINT UNSIGNED);With strict SQL mode enabled, an out of range error occurs:
mysql> SET sql_mode = 'TRADITIONAL';
mysql> INSERT INTO t1 (i1, i2) VALUES(256, 256);
ERROR 1264 (22003): Out of range value for column 'i1' at row 1
mysql> SELECT * FROM t1;
Empty set (0.00 sec)With strict SQL mode not enabled, clipping with warnings occurs:
mysql> SET sql_mode = '';
mysql> INSERT INTO t1 (i1, i2) VALUES(256, 256);
mysql> SHOW WARNINGS;
+---------+------+---------------------------------------------+
| Level   | Code | Message                                     |
+---------+------+---------------------------------------------+
| Warning | 1264 | Out of range value for column 'i1' at row 1 |
| Warning | 1264 | Out of range value for column 'i2' at row 1 |
+---------+------+---------------------------------------------+
mysql> SELECT * FROM t1;
+------+------+
| i1   | i2   |
+------+------+
|  127 |  255 |
+------+------+
        When strict SQL mode is not enabled, column-assignment
        conversions that occur due to clipping are reported as warnings
        for ALTER TABLE,
        LOAD DATA,
        UPDATE, and multiple-row
        INSERT statements. In strict
        mode, these statements fail, and some or all the values are not
        inserted or changed, depending on whether the table is a
        transactional table and other factors. For details, see
        Section 7.1.11, “Server SQL Modes”.
      
        Overflow during numeric expression evaluation results in an
        error. For example, the largest signed
        BIGINT value is
        9223372036854775807, so the following expression produces an
        error:
      
mysql> SELECT 9223372036854775807 + 1;
ERROR 1690 (22003): BIGINT value is out of range in '(9223372036854775807 + 1)'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, an
        error results:
      
mysql> SET sql_mode = '';
Query OK, 0 rows affected (0.00 sec)
mysql> SELECT CAST(0 AS UNSIGNED) - 1;
ERROR 1690 (22003): BIGINT UNSIGNED value is out of range in '(cast(0 as unsigned) - 1)'
        If the NO_UNSIGNED_SUBTRACTION
        SQL mode is enabled, the result is negative:
      
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.