10.5 How MySQL optimizes WHERE clauses

(This section is incomplete; MySQL does many optimizations.)

In general, when you want to make a slow SELECT ... WHERE faster, the first thing to check is whether or not you can add an index. All references between different tables should usually be done with indexes. You can use the EXPLAIN command to determine which indexes are used for a SELECT. EXPLAIN.

Some of the optimizations performed by MySQL are listed below:

  • Removal of unnecessary parentheses:
       ((a AND b) AND c OR (((a AND b) AND (c AND d))))
    -> (a AND b AND c) OR (a AND b AND c AND d)
    
  • Constant folding:
       (a<b AND b=c) AND a=5
    -> b>5 AND b=c AND a=5
    
  • Constant condition removal (needed because of constant folding):
       (B>=5 AND B=5) OR (B=6 AND 5=5) OR (B=7 AND 5=6)
    -> B=5 OR B=6
    
  • Constant expressions used by indexes are evaluated only once.
  • COUNT(*) on a single table without a WHERE is retrieved directly from the table information. This is also done for any NOT NULL expression when used with only one table.
  • Early detection of invalid constant expressions. MySQL quickly detects that some SELECT statements are impossible and returns no rows.
  • HAVING is merged with WHERE if you don't use GROUP BY or group functions (COUNT(), MIN()...)
  • For each sub join, a simpler WHERE is constructed to get a fast WHERE evaluation for each sub join and also to skip records as soon as possible.
  • All constant tables are read first, before any other tables in the query. A constant table is:
    • An empty table or a table with 1 row.
    • A table that is used with a WHERE clause on a UNIQUE index or a PRIMARY KEY, where all index parts are used with constant expressions.
    All the following tables are used as constant tables:
    mysql> SELECT * FROM t WHERE primary_key=1;
    mysql> SELECT * FROM t1,t2
               WHERE t1.primary_key=1 AND t2.primary_key=t1.id;
    
  • The best join combination to join the tables is found by trying all possibilities :(. If all columns in ORDER BY and in GROUP BY come from the same table, then this table is preferred first when joining.
  • If there is an ORDER BY clause and a different GROUP BY clause, or if the ORDER BY or GROUP BY contains columns from tables other than the first table in the join queue, a temporary table is created.
  • If you use SQL_SMALL_RESULT, MySQL will use an in-memory temporary table.
  • As DISTINCT is converted to a GROUP BY on all columns, DISTINCT combined with ORDER BY will in many cases also need a temporary table.
  • Each table index is queried and the best index that spans fewer than 30% of the rows is used. If no such index can be found, a quick table scan is used.
  • In some cases, MySQL can read rows from the index without even consulting the data file. If all columns used from the index are numeric, then only the index tree is used to resolve the query.
  • Before each record is output, those that do not match the HAVING clause are skipped.

Some examples of queries that are very fast:

mysql> SELECT COUNT(*) FROM tbl_name;
mysql> SELECT MIN(key_part1),MAX(key_part1) FROM tbl_name;
mysql> SELECT MAX(key_part2) FROM tbl_name
           WHERE key_part_1=constant;
mysql> SELECT ... FROM tbl_name
           ORDER BY key_part1,key_part2,... LIMIT 10;
mysql> SELECT ... FROM tbl_name
           ORDER BY key_part1 DESC,key_part2 DESC,... LIMIT 10;

The following queries are resolved using only the index tree (assuming the indexed columns are numeric):

mysql> SELECT key_part1,key_part2 FROM tbl_name WHERE key_part1=val;
mysql> SELECT COUNT(*) FROM tbl_name
           WHERE key_part1=val1 AND key_part2=val2;
mysql> SELECT key_part2 FROM tbl_name GROUP BY key_part1;

The following queries use indexing to retrieve the rows in sorted order without a separate sorting pass:

mysql> SELECT ... FROM tbl_name ORDER BY key_part1,key_part2,...
mysql> SELECT ... FROM tbl_name ORDER BY key_part1 DESC,key_part2 DESC,...