MySQL can perform the same optimization on
col_name IS NULL
that it can use with col_name
= constant_value.
For example, MySQL can use indexes and ranges to search for
NULL with IS NULL.
SELECT * FROMtbl_nameWHEREkey_colIS NULL; SELECT * FROMtbl_nameWHEREkey_col<=> NULL; SELECT * FROMtbl_nameWHEREkey_col=const1ORkey_col=const2ORkey_colIS NULL;
If a WHERE clause includes a
col_name IS NULL
condition for a column that is declared as NOT
NULL, that expression is optimized away. This
optimization does not occur in cases when the column might
produce NULL anyway; for example, if it comes
from a table on the right side of a LEFT
JOIN.
MySQL 5.0 can also optimize the combination
, a form
that is common in resolved subqueries.
col_name =
expr AND
col_name IS NULLEXPLAIN shows ref_or_null
when this optimization is used.
This optimization can handle one IS NULL for
any key part.
Some examples of queries that are optimized, assuming that there
is an index on columns a and
b of table t2:
SELECT * FROM t1 WHERE t1.a=expr OR t1.a IS NULL;
SELECT * FROM t1, t2 WHERE t1.a=t2.a OR t2.a IS NULL;
SELECT * FROM t1, t2
WHERE (t1.a=t2.a OR t2.a IS NULL) AND t2.b=t1.b;
SELECT * FROM t1, t2
WHERE t1.a=t2.a AND (t2.b=t1.b OR t2.b IS NULL);
SELECT * FROM t1, t2
WHERE (t1.a=t2.a AND t2.a IS NULL AND ...)
OR (t1.a=t2.a AND t2.a IS NULL AND ...);
ref_or_null works by first doing a read on
the reference key, and then a separate search for rows with a
NULL key value.
Note that the optimization can handle only one IS
NULL level. In the following query, MySQL uses key
lookups only on the expression (t1.a=t2.a AND t2.a IS
NULL) and is not able to use the key part on
b:
SELECT * FROM t1, t2
WHERE (t1.a=t2.a AND t2.a IS NULL)
OR (t1.b=t2.b AND t2.b IS NULL);
Ésta es una traducción del manual de referencia de MySQL, que puede encontrarse en dev.mysql.com. El manual de referencia original de MySQL está escrito en inglés, y esta traducción no necesariamente está tan actualizada como la versión original. Para cualquier sugerencia sobre la traducción y para señalar errores de cualquier tipo, no dude en dirigirse a mysql-es@vespito.com.
