Implicit type conversion takes place when MariaDB is using operands or different types, in order to make the operands compatible.
It is best practice not to rely upon implicit conversion; rather use CAST to explicitly convert types.
Note that if a string column is being compared with a numeric value, MariaDB will not use the index on the column, as there are numerous alternatives that may evaluate as equal (see examples below).
Converting a string to a number:
SELECT 15+'15'; +---------+ | 15+'15' | +---------+ | 30 | +---------+
Converting a number to a string:
SELECT CONCAT(15,'15'); +-----------------+ | CONCAT(15,'15') | +-----------------+ | 1515 | +-----------------+
Floating point number errors:
SELECT '9746718491924563214' = 9746718491924563213; +---------------------------------------------+ | '9746718491924563214' = 9746718491924563213 | +---------------------------------------------+ | 1 | +---------------------------------------------+
Numeric equivalence with strings:
SELECT '5' = 5; +---------+ | '5' = 5 | +---------+ | 1 | +---------+ SELECT ' 5' = 5; +------------+ | ' 5' = 5 | +------------+ | 1 | +------------+ SELECT ' 5 ' = 5; +--------------+ | ' 5 ' = 5 | +--------------+ | 1 | +--------------+ 1 row in set, 1 warning (0.000 sec) SHOW WARNINGS; +-------+------+--------------------------------------------+ | Level | Code | Message | +-------+------+--------------------------------------------+ | Note | 1292 | Truncated incorrect DOUBLE value: ' 5 ' | +-------+------+--------------------------------------------+
As a result of the above, MariaDB cannot use the index when comparing a string with a numeric value in the example below:
CREATE TABLE t (a VARCHAR(10), b VARCHAR(10), INDEX idx_a (a));
INSERT INTO t VALUES ('1', '1'), ('2', '2'), ('3', '3'), ('4', '4'), ('5', '5'), ('1', '5');
EXPLAIN SELECT * FROM t WHERE a = '3' \G
*************************** 1. row ***************************
id: 1
select_type: SIMPLE
table: t
type: ref
possible_keys: idx_a
key: idx_a
key_len: 13
ref: const
rows: 1
Extra: Using index condition
EXPLAIN SELECT * FROM t WHERE a = 3 \G
*************************** 1. row ***************************
id: 1
select_type: SIMPLE
table: t
type: ALL
possible_keys: idx_a
key: NULL
key_len: NULL
ref: NULL
rows: 6
Extra: Using where
Implicit type conversion also takes place on dyadic arithmetic operations (+,-,*,/). MariaDB chooses the minimum data type that is guaranteed to fit the result and converts both arguments to the result data type.
For addition (+), subtraction (-) and multiplication (*), the result data type is chosen as follows:
For division (/), the result data type is chosen as follows:
Note, the above rules mean that when an argument of a temporal data type appears in addition or subtraction, it's treated as a number by default.
SELECT TIME'10:20:30' + 1; +--------------------+ | TIME'10:20:30' + 1 | +--------------------+ | 102031 | +--------------------+
In order to do temporal addition or subtraction instead, use the DATE_ADD() or DATE_SUB() functions, or an INTERVAL expression as the second argument:
SELECT TIME'10:20:30' + INTERVAL 1 SECOND; +------------------------------------+ | TIME'10:20:30' + INTERVAL 1 SECOND | +------------------------------------+ | 10:20:31 | +------------------------------------+
SELECT "2.2" + 3; +-----------+ | "2.2" + 3 | +-----------+ | 5.2 | +-----------+ SELECT 2.2 + 3; +---------+ | 2.2 + 3 | +---------+ | 5.2 | +---------+ SELECT 2.2 / 3; +---------+ | 2.2 / 3 | +---------+ | 0.73333 | +---------+ SELECT "2.2" / 3; +--------------------+ | "2.2" / 3 | +--------------------+ | 0.7333333333333334 | +--------------------+
© 2019 MariaDB
Licensed under the Creative Commons Attribution 3.0 Unported License and the GNU Free Documentation License.
https://mariadb.com/kb/en/type-conversion/