Optimizing SELECT Statements and Other Queries

First, one factor affects all statements: The more complex your permission setup is, the more overhead you will have.

Using simpler permissions when you issue GRANT statements enables MySQL to reduce permission-checking overhead when clients execute statements. For example, if you don't grant any table-level or column-level privileges, the server need not ever check the contents of the tables_priv and columns_priv tables. Similarly, if you place no resource limits on any accounts, the server does not have to perform resource counting. If you have a very high query volume, it may be worth the time to use a simplified grant structure to reduce permission-checking overhead.

If your problem is with some specific MySQL expression or function, you can use the BENCHMARK() function from the mysql client program to perform a timing test. Its syntax is BENCHMARK(loop_count,expression). For example:

mysql> SELECT BENCHMARK(1000000,1+1);
+------------------------+
| BENCHMARK(1000000,1+1) |
+------------------------+
|                      0 |
+------------------------+
1 row in set (0.32 sec)

This result was obtained on a Pentium II 400MHz system. It shows that MySQL can execute 1,000,000 simple addition expressions in 0.32 seconds on that system.

All MySQL functions should be very optimized, but there may be some exceptions. BENCHMARK() is a great tool to find out if this is a problem with your query.

EXPLAIN Syntax (Get Information About a SELECT)

EXPLAIN tbl_name

Or:

EXPLAIN SELECT select_options

The EXPLAIN statement can be used either as a synonym for DESCRIBE or as a way to obtain information about how MySQL will execute a SELECT statement:

  • The EXPLAIN tbl_name syntax is synonymous with DESCRIBE tbl_name or SHOW COLUMNS FROM tbl_name.

  • When you precede a SELECT statement with the keyword EXPLAIN, MySQL explains how it would process the SELECT, providing information about how tables are joined and in which order.

This section provides information about the second use of EXPLAIN.

With the help of EXPLAIN, you can see when you must add indexes to tables to get a faster SELECT that uses indexes to find records.

If you have a problem with incorrect index usage, you should run ANALYZE TABLE to update table statistics such as cardinality of keys, which can affect the choices the optimizer makes. See ANALYZE TABLE.

You can also see whether the optimizer joins the tables in an optimal order. To force the optimizer to use a join order corresponding to the order in which the tables are named in the SELECT statement, begin the statement with SELECT STRAIGHT_JOIN rather than just SELECT.

EXPLAIN returns a row of information for each table used in the SELECT statement. The tables are listed in the output in the order that MySQL would read them while processing the query. MySQL resolves all joins using a single-sweep multi-join method. This means that MySQL reads a row from the first table, then finds a matching row in the second table, then in the third table, and so on. When all tables are processed, it outputs the selected columns and backtracks through the table list until a table is found for which there are more matching rows. The next row is read from this table and the process continues with the next table.

In MySQL version 4.1, the EXPLAIN output format was changed to work better with constructs such as UNION statements, subqueries, and derived tables. Most notable is the addition of two new columns: id and select_type. You will not see these columns when using servers older than MySQL 4.1.

Each output row from EXPLAIN provides information about one table, and each row consists of the following columns:

id

The SELECT identifier. This is the sequential number of the SELECT within the query.

select_type

The type of SELECT, which can be any of the following:

SIMPLE

Simple SELECT (not using UNION or subqueries)

PRIMARY

Outermost SELECT

UNION

Second or later SELECT statement in a UNION

DEPENDENT UNION

Second or later SELECT statement in a UNION, dependent on outer subquery

SUBQUERY

First SELECT in subquery

DEPENDENT SUBQUERY

First SELECT in subquery, dependent on outer subquery

DERIVED

Derived table SELECT (subquery in FROM clause)

table

The table to which the row of output refers.

type

The join type. The different join types are listed here, ordered from the best type to the worst:

system

The table has only one row (= system table). This is a special case of the const join type.

const

The table has at most one matching row, which will be read at the start of the query. Because there is only one row, values from the column in this row can be regarded as constants by the rest of the optimizer. const tables are very fast because they are read only once!

const is used when you compare all parts of a PRIMARY KEY or UNIQUE index with constant values. In the following queries, tbl_name can be used as a const table:

SELECT * FROM tbl_name WHERE primary_key=1;

SELECT * FROM tbl_name
WHERE primary_key_part1=1 AND primary_key_part2=2;
eq_ref

One row will be read from this table for each combination of rows from the previous tables. Other than the const types, this is the best possible join type. It is used when all parts of an index are used by the join and the index is a PRIMARY KEY or UNIQUE index.

eq_ref can be used for indexed columns that are compared using the = operator. The comparison value can be a constant or an expression that uses columns from tables that are read before this table.

In the following examples, MySQL can use an eq_ref join to process ref_table:

SELECT * FROM ref_table,other_table
WHERE ref_table.key_column=other_table.column;

SELECT * FROM ref_table,other_table
WHERE ref_table.key_column_part1=other_table.column
AND ref_table.key_column_part2=1;
ref

All rows with matching index values will be read from this table for each combination of rows from the previous tables. ref is used if the join uses only a leftmost prefix of the key or if the key is not a PRIMARY KEY or UNIQUE index (in other words, if the join cannot select a single row based on the key value). If the key that is used matches only a few rows, this is a good join type.

ref can be used for indexed columns that are compared using the = operator.

In the following examples, MySQL can use a ref join to process ref_table:

SELECT * FROM ref_table WHERE key_column=expr;

SELECT * FROM ref_table,other_table
WHERE ref_table.key_column=other_table.column;

SELECT * FROM ref_table,other_table
WHERE ref_table.key_column_part1=other_table.column
AND ref_table.key_column_part2=1;
ref_or_null

This join type is like ref, but with the addition that MySQL will do an extra search for rows that contain NULL values. This join type optimization is new for MySQL 4.1.1 and is mostly used when resolving subqueries.

In the following examples, MySQL can use a ref_or_null join to process ref_table:

SELECT * FROM ref_table
WHERE key_column=expr OR key_column IS NULL;

See IS NULL optimization.

index_merge

This join type indicates that the Index Merge optimization is used. In this case, the key column contains a list of indexes used, and key_len contains a list of the longest key parts for the indexes used. For more information, see the section called “Index Merge Optimization”.

unique_subquery

This type replaces ref for some IN subqueries of the following form:

value IN (SELECT primary_key FROM single_table WHERE some_expr)

unique_subquery is just an index lookup function that replaces the subquery completely for better efficiency.

index_subquery

This join type is similar to unique_subquery. It replaces IN subqueries, but it works for non-unique indexes in subqueries of the following form:

value IN (SELECT key_column FROM single_table WHERE some_expr)
range

Only rows that are in a given range will be retrieved, using an index to select the rows. The key column indicates which index is used. The key_len contains the longest key part that was used. The ref column will be NULL for this type.

range can be used for when a key column is compared to a constant using any of the =, <>, >, >=, <, <=, IS NULL, <=>, BETWEEN, or IN operators:

SELECT * FROM tbl_name
WHERE key_column = 10;

SELECT * FROM tbl_name
WHERE key_column BETWEEN 10 and 20;

SELECT * FROM tbl_name
WHERE key_column IN (10,20,30);

SELECT * FROM tbl_name
WHERE key_part1= 10 AND key_part2 IN (10,20,30);
index

This join type is the same as ALL, except that only the index tree is scanned. This usually is faster than ALL, because the index file usually is smaller than the data file.

MySQL can use this join type when the query uses only columns that are part of a single index.

ALL

A full table scan will be done for each combination of rows from the previous tables. This is normally not good if the table is the first table not marked const, and usually very bad in all other cases. Normally, you can avoid ALL by adding indexes that allow row retrieval from the table based on constant values or column values from earlier tables.

possible_keys

The possible_keys column indicates which indexes MySQL could use to find the rows in this table. Note that this column is totally independent of the order of the tables as displayed in the output from EXPLAIN. That means that some of the keys in possible_keys might not be usable in practice with the generated table order.

If this column is NULL, there are no relevant indexes. In this case, you may be able to improve the performance of your query by examining the WHERE clause to see whether it refers to some column or columns that would be suitable for indexing. If so, create an appropriate index and check the query with EXPLAIN again. See ALTER TABLE.

To see what indexes a table has, use SHOW INDEX FROM tbl_name.

key

The key column indicates the key (index) that MySQL actually decided to use. The key is NULL if no index was chosen. To force MySQL to use or ignore an index listed in the possible_keys column, use FORCE INDEX, USE INDEX, or IGNORE INDEX in your query. See SELECT.

For MyISAM and BDB tables, running ANALYZE TABLE will help the optimizer choose better indexes. For MyISAM tables, myisamchk --analyze will do the same. See ANALYZE TABLE and the section called “Table Maintenance and Crash Recovery”.

key_len

The key_len column indicates the length of the key that MySQL decided to use. The length is NULL if the key column says NULL. Note that the value of key_len allows you to determine how many parts of a multiple-part key MySQL will actually use.

ref

The ref column shows which columns or constants are used with the key to select rows from the table.

rows

The rows column indicates the number of rows MySQL believes it must examine to execute the query.

Extra

This column contains additional information about how MySQL will resolve the query. Here is an explanation of the different text strings that can appear in this column:

Distinct

MySQL will stop searching for more rows for the current row combination after it has found the first matching row.

Not exists

MySQL was able to do a LEFT JOIN optimization on the query and will not examine more rows in this table for the previous row combination after it finds one row that matches the LEFT JOIN criteria.

Here is an example of the type of query that can be optimized this way:

SELECT * FROM t1 LEFT JOIN t2 ON t1.id=t2.id
WHERE t2.id IS NULL;

Assume that t2.id is defined as NOT NULL. In this case, MySQL will scan t1 and look up the rows in t2 using the values of t1.id. If MySQL finds a matching row in t2, it knows that t2.id can never be NULL, and will not scan through the rest of the rows in t2 that have the same id value. In other words, for each row in t1, MySQL needs to do only a single lookup in t2, regardless of how many rows actually match in t2.

range checked for each record (index map: #)

MySQL found no good index to use, but found that some of indexes might be used once column values from preceding tables are known. For each row combination in the preceding tables, MySQL will check whether it is possible to use a range or index_merge access method to retrieve rows. The applicability criteria are as described in the section called “Range Optimization” and the section called “Index Merge Optimization”, with the exception that all column values for the preceding table are known and considered to be constants.

This is not very fast, but is faster than performing a join with no index at all.

Using filesort

MySQL will need to do an extra pass to find out how to retrieve the rows in sorted order. The sort is done by going through all rows according to the join type and storing the sort key and pointer to the row for all rows that match the WHERE clause. The keys then are sorted and the rows are retrieved in sorted order. See ORDER BY optimization.

Using index

The column information is retrieved from the table using only information in the index tree without having to do an additional seek to read the actual row. This strategy can be used when the query uses only columns that are part of a single index.

Using temporary

To resolve the query, MySQL will need to create a temporary table to hold the result. This typically happens if the query contains GROUP BY and ORDER BY clauses that list columns differently.

Using where

A WHERE clause will be used to restrict which rows to match against the next table or send to the client. Unless you specifically intend to fetch or examine all rows from the table, you may have something wrong in your query if the Extra value is not Using where and the table join type is ALL or index.

If you want to make your queries as fast as possible, you should look out for Extra values of Using filesort and Using temporary.

Using sort_union(...), Using union(...), Using intersect(...),

These indicate how index scans are merged for the index_merge join type. See the section called “Index Merge Optimization” for more information.

Using index for group-by

Similar to the Using index way of accessing a table, Using index for group-by indicates that MySQL found an index that can be used to retrieve all columns of a GROUP BY or DISTINCT query without any extra disk access to the actual table. Additionally, the index will be used in the most efficient way so that for each group, only a few index entries will be read. For details, see GROUP BY optimization.

You can get a good indication of how good a join is by taking the product of the values in the rows column of the EXPLAIN output. This should tell you roughly how many rows MySQL must examine to execute the query. If you restrict queries with the max_join_size system variable, this product also is used to determine which multiple-table SELECT statements to execute. See the section called “Tuning Server Parameters”.

The following example shows how a multiple-table join can be optimized progressively based on the information provided by EXPLAIN.

Suppose that you have the SELECT statement shown here and you plan to examine it using EXPLAIN:

EXPLAIN SELECT tt.TicketNumber, tt.TimeIn,
            tt.ProjectReference, tt.EstimatedShipDate,
            tt.ActualShipDate, tt.ClientID,
            tt.ServiceCodes, tt.RepetitiveID,
            tt.CurrentProcess, tt.CurrentDPPerson,
            tt.RecordVolume, tt.DPPrinted, et.COUNTRY,
            et_1.COUNTRY, do.CUSTNAME
        FROM tt, et, et AS et_1, do
        WHERE tt.SubmitTime IS NULL
            AND tt.ActualPC = et.EMPLOYID
            AND tt.AssignedPC = et_1.EMPLOYID
            AND tt.ClientID = do.CUSTNMBR;

For this example, make the following assumptions:

  • The columns being compared have been declared as follows:

    TableColumnColumn Type
    ttActualPCCHAR(10)
    ttAssignedPCCHAR(10)
    ttClientIDCHAR(10)
    etEMPLOYIDCHAR(15)
    doCUSTNMBRCHAR(15)
  • The tables have the following indexes:

    TableIndex
    ttActualPC
    ttAssignedPC
    ttClientID
    etEMPLOYID (primary key)
    doCUSTNMBR (primary key)
  • The tt.ActualPC values are not evenly distributed.

Initially, before any optimizations have been performed, the EXPLAIN statement produces the following information:

table type possible_keys key  key_len ref  rows  Extra
et    ALL  PRIMARY       NULL NULL    NULL 74
do    ALL  PRIMARY       NULL NULL    NULL 2135
et_1  ALL  PRIMARY       NULL NULL    NULL 74
tt    ALL  AssignedPC,   NULL NULL    NULL 3872
           ClientID,
           ActualPC
      range checked for each record (key map: 35)

Because type is ALL for each table, this output indicates that MySQL is generating a Cartesian product of all the tables; that is, every combination of rows. This will take quite a long time, because the product of the number of rows in each table must be examined. For the case at hand, this product is 74 * 2135 * 74 * 3872 = 45,268,558,720 rows. If the tables were bigger, you can only imagine how long it would take.

One problem here is that MySQL can use indexes on columns more efficiently if they are declared the same. (For ISAM tables, indexes may not be used at all unless the columns are declared the same.) In this context, VARCHAR and CHAR are the same unless they are declared as different lengths. Because tt.ActualPC is declared as CHAR(10) and et.EMPLOYID is declared as CHAR(15), there is a length mismatch.

To fix this disparity between column lengths, use ALTER TABLE to lengthen ActualPC from 10 characters to 15 characters:

mysql> ALTER TABLE tt MODIFY ActualPC VARCHAR(15);

Now tt.ActualPC and et.EMPLOYID are both VARCHAR(15). Executing the EXPLAIN statement again produces this result:

table type   possible_keys key     key_len ref         rows    Extra
tt    ALL    AssignedPC,   NULL    NULL    NULL        3872    Using
             ClientID,                                         where
             ActualPC
do    ALL    PRIMARY       NULL    NULL    NULL        2135
      range checked for each record (key map: 1)
et_1  ALL    PRIMARY       NULL    NULL    NULL        74
      range checked for each record (key map: 1)
et    eq_ref PRIMARY       PRIMARY 15      tt.ActualPC 1

This is not perfect, but is much better: The product of the rows values is now less by a factor of 74. This version is executed in a couple of seconds.

A second alteration can be made to eliminate the column length mismatches for the tt.AssignedPC = et_1.EMPLOYID and tt.ClientID = do.CUSTNMBR comparisons:

mysql> ALTER TABLE tt MODIFY AssignedPC VARCHAR(15),
    ->                MODIFY ClientID   VARCHAR(15);

Now EXPLAIN produces the output shown here:

table type   possible_keys key      key_len ref           rows Extra
et    ALL    PRIMARY       NULL     NULL    NULL          74
tt    ref    AssignedPC,   ActualPC 15      et.EMPLOYID   52   Using
             ClientID,                                         where
             ActualPC
et_1  eq_ref PRIMARY       PRIMARY  15      tt.AssignedPC 1
do    eq_ref PRIMARY       PRIMARY  15      tt.ClientID   1

This is almost as good as it can get.

The remaining problem is that, by default, MySQL assumes that values in the tt.ActualPC column are evenly distributed, and that is not the case for the tt table. Fortunately, it is easy to tell MySQL to analyze the key distribution:

mysql> ANALYZE TABLE tt;

Now the join is perfect, and EXPLAIN produces this result:

table type   possible_keys key     key_len ref           rows Extra
tt    ALL    AssignedPC    NULL    NULL    NULL          3872 Using
             ClientID,                                        where
             ActualPC
et    eq_ref PRIMARY       PRIMARY 15      tt.ActualPC   1
et_1  eq_ref PRIMARY       PRIMARY 15      tt.AssignedPC 1
do    eq_ref PRIMARY       PRIMARY 15      tt.ClientID   1

Note that the rows column in the output from EXPLAIN is an educated guess from the MySQL join optimizer. You should check whether the numbers are even close to the truth. If not, you may get better performance by using STRAIGHT_JOIN in your SELECT statement and trying to list the tables in a different order in the FROM clause.

Estimating Query Performance

In most cases, you can estimate the performance by counting disk seeks. For small tables, you can usually find a row in one disk seek (because the index is probably cached). For bigger tables, you can estimate that, using B-tree indexes, you will need this many seeks to find a row: log(row_count) / log(index_block_length / 3 * 2 / (index_length + data_pointer_length)) + 1.

In MySQL, an index block is usually 1024 bytes and the data pointer is usually 4 bytes. For a 500,000-row table with an index length of 3 bytes (medium integer), the formula indicates log(500,000)/log(1024/3*2/(3+4)) + 1 = 4 seeks.

This index would require storage of about 500,000 * 7 * 3/2 = 5.2MB (assuming a typical index buffer fill ratio of 2/3), so you will probably have much of the index in memory and you will probably need only one or two calls to read data to find the row.

For writes, however, you will need four seek requests (as above) to find where to place the new index and normally two seeks to update the index and write the row.

Note that the preceding discussion doesn't mean that your application performance will slowly degenerate by log N! As long as everything is cached by the OS or SQL server, things will become only marginally slower as the table gets bigger. After the data gets too big to be cached, things will start to go much slower until your applications is only bound by disk-seeks (which increase by log N). To avoid this, increase the key cache size as the data grows. For MyISAM tables, the key cache size is controlled by the key_buffer_size system variable. See the section called “Tuning Server Parameters”.

Speed of SELECT Queries

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

Some general tips for speeding up queries on MyISAM tables:

  • To help MySQL optimize queries better, use ANALYZE TABLE or run myisamchk --analyze on a table after it has been loaded with data. This updates a value for each index part that indicates the average number of rows that have the same value. (For unique indexes, this is always 1.) MySQL will use this to decide which index to choose when you join two tables based on a non-constant expression. You can check the result from the table analysis by using SHOW INDEX FROM tbl_name and examining the Cardinality value. myisamchk --description --verbose shows index distribution information.

  • To sort an index and data according to an index, use myisamchk --sort-index --sort-records=1 (if you want to sort on index 1). This is a good way to make queries faster if you have a unique index from which you want to read all records in order according to the index. Note that the first time you sort a large table this way, it may take a long time.

How MySQL Optimizes WHERE Clauses

This section discusses optimizations that can be made for processing WHERE clauses. The examples use SELECT statements, but the same optimizations apply for WHERE clauses in DELETE and UPDATE statements.

Note that work on the MySQL optimizer is ongoing, so this section is incomplete. MySQL does many optimizations, not all of which are documented here.

Some of the optimizations performed by MySQL are listed here:

  • 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 for MyISAM and HEAP tables. 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(), and so on).

  • For each table in a join, a simpler WHERE is constructed to get a fast WHERE evaluation for the table 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 any of the following:

    • An empty table or a table with one row.

    • A table that is used with a WHERE clause on a PRIMARY KEY or a UNIQUE index, where all index parts are compared to constant expressions and are defined as NOT NULL.

    All of the following tables are used as constant tables:

    SELECT * FROM t WHERE primary_key=1;
    SELECT * FROM t1,t2
        WHERE t1.primary_key=1 AND t2.primary_key=t1.id;
    
  • The best join combination for joining the tables is found by trying all possibilities. If all columns in ORDER BY and GROUP BY clauses come from the same table, that 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 uses an in-memory temporary table.

  • Each table index is queried, and the best index is used unless the optimizer believes that it will be more efficient to use a table scan. At one time, a scan was used based on whether the best index spanned more than 30% of the table. Now the optimizer is more complex and bases its estimate on additional factors such as table size, number of rows, and I/O block size, so a fixed percentage no longer determines the choice between using an index or a scan.

  • 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, 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:

SELECT COUNT(*) FROM tbl_name;

SELECT MIN(key_part1),MAX(key_part1) FROM tbl_name;

SELECT MAX(key_part2) FROM tbl_name
    WHERE key_part1=constant;

SELECT ... FROM tbl_name
    ORDER BY key_part1,key_part2,... LIMIT 10;

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 that the indexed columns are numeric:

SELECT key_part1,key_part2 FROM tbl_name WHERE key_part1=val;

SELECT COUNT(*) FROM tbl_name
    WHERE key_part1=val1 AND key_part2=val2;

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:

SELECT ... FROM tbl_name
    ORDER BY key_part1,key_part2,... ;

SELECT ... FROM tbl_name
    ORDER BY key_part1 DESC, key_part2 DESC, ... ;

Range Optimization

The range access method uses a single index to retrieve a subset of table records that are contained within one or several index value intervals. It can be used for a single-part or multiple-part index. A detailed description of how intervals are extracted from the WHERE clause is given in the following sections.

Range Access Method for Single-Part Indexes

For a single-part index, index value intervals can be conveniently represented by corresponding conditions in the WHERE clause, so we'll talk about “range conditions” instead of intervals.

The definition of a range condition for a single-part index is as follows:

  • For both BTREE and HASH indexes, comparison of a key part with a constant value is a range condition when using the =, <=>, IN, IS NULL, or IS NOT NULL operators.

  • For BTREE indexes, comparison of a key part with a constant value is a range condition when using the >, <, >=, <=, BETWEEN, !=, or <> operators, or LIKE 'pattern' (where 'pattern' doesn't start with a wildcard).

  • For all types of indexes, multiple range conditions combined with OR or AND form a range condition.

“Constant value” in the preceding descriptions means one of the following:

  • A constant from the query string

  • A column of a const or system table from the the same join

  • The result of an uncorrelated subquery

  • Any expression composed entirely from subexpressions of the preceding types

Here are some examples of queries with range conditions in the WHERE clause:

SELECT * FROM t1 WHERE key_col > 1 AND key_col < 10;

SELECT * FROM t1 WHERE key_col = 1 OR key_col IN (15,18,20);

SELECT * FROM t1 WHERE key_col LIKE 'ab%' OR key_col BETWEEN
'bar' AND 'foo';

Note that some non-constant values may be converted to constants during the constant propagation phase.

MySQL tries to extract range conditions from the WHERE clause for each of the possible indexes. During the extraction process, conditions that can't be used for constructing the range condition are dropped, conditions that produce overlapping ranges are combined, and conditions that produce empty ranges are removed.

For example, consider the following statement, where key1 is an indexed column and nonkey is not indexed:

SELECT * FROM t1 WHERE
   (key1 < 'abc' AND (key1 LIKE 'abcde%' OR key1 LIKE '%b')) OR
   (key1 < 'bar' AND nonkey = 4) OR
   (key1 < 'uux' AND key1 > 'z');

The extraction process for key key1 is as follows:

  1. Start with original WHERE clause:

    (key1 < 'abc' AND (key1 LIKE 'abcde%' OR key1 LIKE '%b')) OR
    (key1 < 'bar' AND nonkey = 4) OR
    (key1 < 'uux' AND key1 > 'z')
    
  2. Remove nonkey = 4 and key1 LIKE '%b' because they cannot be used for a range scan. The right way to remove them is to replace them with TRUE, so that we don't miss any matching records when doing the range scan. Having replaced them with TRUE, we get:

    (key1 < 'abc' AND (key1 LIKE 'abcde%' OR TRUE)) OR
    (key1 < 'bar' AND TRUE) OR
    (key1 < 'uux' AND key1 > 'z')
    
  3. Collapse conditions that are always true or false:

    • (key1 LIKE 'abcde%' OR TRUE) is always true

    • (key1 < 'uux' AND key1 > 'z') is always false

    Replacing these conditions with constants, we get:

    (key1 < 'abc' AND TRUE) OR (key1 < 'bar' AND TRUE) OR (FALSE)
    

    Removing unnecessary TRUE and FALSE constants, we obtain

    (key1 < 'abc') OR (key1 < 'bar')
    
  4. Combining overlapping intervals into one yields the final condition to be used for the range scan:

    (key1 < 'bar')
    

In general (and as demonstrated in the example), the condition used for a range scan is less restrictive than the WHERE clause. MySQL will perform an additional check to filter out rows that satisfy the range condition but not the full WHERE clause.

The range condition extraction algorithm can handle nested AND/OR constructs of arbitrary depth, and its output doesn't depend on the order in which conditions appear in WHERE clause.

Range Access Method for Multiple-Part Indexes

Range conditions on a multiple-part index are an extension of range conditions for a single-part index. A range condition on a multiple-part index restricts index records to lie within one or several key tuple intervals. Key tuple intervals are defined over a set of key tuples, using ordering from the index.

For example, consider a multiple-part index defined as key1(key_part1, key_part2, key_part3), and the following set of key tuples listed in key order:

key_part1  key_part2  key_part3
  NULL       1          'abc'
  NULL       1          'xyz'
  NULL       2          'foo'
   1         1          'abc'
   1         1          'xyz'
   1         2          'abc'
   2         1          'aaa'

The condition key_part1 = 1 defines this interval:

(1, -inf, -inf) <= (key_part1, key_part2, key_part3) < (1, +inf, +inf)

The interval covers the 4th, 5th, and 6th tuples in the preceding data set and can be used by the range access method.

By contrast, the condition key_part3 = 'abc' does not define a single interval and cannot be used by the range access method.

The following descriptions indicate how range conditions work for multiple-part indexes in greater detail.

  • For HASH indexes, each interval containing identical values can be used. This means that the interval can be produced only for conditions in the following form:

        key_part1 cmp const1
    AND key_part2 cmp const2
    AND ...
    AND key_partN cmp constN;
    

    Here, const1, const2, ... are constants, cmp is one of the =, <=>, or IS NULL comparison operators, and the conditions cover all index parts. (That is, there are N conditions, one for each part of an N-part index.)

    See the section called “Range Access Method for Single-Part Indexes” for the definition of what is considered to be a constant.

    For example, the following is a range condition for a three-part HASH index:

    key_part1 = 1 AND key_part2 IS NULL AND key_part3 = 'foo'
    
  • For a BTREE index, an interval might be usable for conditions combined with AND, where each condition compares a key part with a constant value using =, <=>, IS NULL, >, <, >=, <=, !=, <>, BETWEEN, or LIKE 'pattern' (where 'pattern' doesn't start with a wildcard). An interval can be used as long as it is possible to determine a single key tuple containing all records that match the condition (or two intervals if <> or != is used). For example, for this condition:

    key_part1 = 'foo' AND key_part2 >= 10 AND key_part3 > 10
    

    The single interval will be:

    ('foo', 10, 10)
       < (key_part1, key_part2, key_part3)
          < ('foo', +inf, +inf)
    

    It is possible that the created interval will contain more records than the initial condition. For example, the preceding interval includes the value ('foo', 11, 0), which does not satisfy the original condition.

  • If conditions that cover sets of records contained within intervals are combined with OR, they form a condition that covers a set of records contained within the union of their intervals. If the conditions are combined with AND, they form a condition that covers a set of records contained within the intersection of their intervals. For example, for this condition on a two-part index:

    (key_part1 = 1 AND key_part2 < 2)
    OR (key_part1 > 5)
    

    The intervals will be:

    (1, -inf) < (key_part1, key_part2) < (1, 2)
    (5, -inf) < (key_part1, key_part2)
    

    In this example, the interval on the first line uses one key part for the left bound and two key parts for the right bound. The interval on the second line uses only one key part. The key_len column in the EXPLAIN output indicates the maximum length of the key prefix used.

    In some cases, key_len may indicate that a key part was used, but that might be not what you would expect. Suppose that key_part1 and key_part2 can be NULL. Then the key_len column will display two key part lengths for the following condition:

    key_part1 >= 1 AND key_part2 < 2
    

    But in fact, the condition will be converted to this:

    key_part1 >= 1 AND key_part2 IS NOT NULL
    

the section called “Range Access Method for Single-Part Indexes” describes how optimizations are performed to combine or eliminate intervals for range conditions on single-part index. Analogous steps are performed for range conditions on multiple-part keys.

Index Merge Optimization

The Index Merge (index_merge) method is used to retrieve rows with several ref, ref_or_null, or range scans and merge the results into one. This method is employed when the table condition is a disjunction of conditions for which ref, ref_or_null, or range could be used with different keys.

This “join” type optimization is new in MySQL 5.0.0, and represents a significant change in behavior with regard to indexes, because the old rule was that the server is only ever able to use at most one index for each referenced table.

In EXPLAIN output, this method appears as index_merge in the type column. In this case, the key column contains a list of indexes used, and key_len contains a list of the longest key parts for those indexes.

Examples:

SELECT * FROM tbl_name WHERE key_part1 = 10 OR key_part2 = 20;

SELECT * FROM tbl_name
    WHERE (key_part1 = 10 OR key_part2 = 20) AND non_key_part=30;

SELECT * FROM t1, t2
    WHERE (t1.key1 IN (1,2) OR t1.key2 LIKE 'value%')
    AND t2.key1=t1.some_col;

SELECT * FROM t1, t2
    WHERE t1.key1=1
    AND (t2.key1=t1.some_col OR t2.key2=t1.some_col2);

The Index Merge method has several access algorithms (seen in the Extra field of EXPLAIN output):

  • intersection

  • union

  • sort-union

The following sections describe these methods in greater detail.

Note: The Index Merge optimization algorithm has the following known deficiencies:

  • If a range scan is possible on some key, Index Merge will not be considered. For example, consider this query:

    SELECT * FROM t1 WHERE (goodkey1 < 10 OR goodkey2 < 20) AND badkey < 30;
    

    For this query, two plans are possible:

    1. An Index Merge scan using the (goodkey1 < 10 OR goodkey2 < 20) condition.

    2. A range scan using the badkey < 30 condition.

    However, the optimizer will only consider the second plan. If that not what you want, you can make the optimizer consider index_merge by using IGNORE INDEX or FORCE INDEX. The following queries will be executed using Index Merge:

    SELECT * FROM t1 FORCE INDEX(goodkey1,goodkey2)
    WHERE (goodkey1 < 10 OR goodkey2 < 20) AND badkey < 30;
    
    SELECT * FROM t1 IGNORE INDEX(badkey)
    WHERE (goodkey1 < 10 OR goodkey2 < 20) AND badkey < 30;
    
  • If your query has a complex WHERE clause with deep AND/OR nesting and MySQL doesn't choose the optimal plan, try distributing terms using the following identity laws:

    (x AND y) OR z = (x OR z) AND (y OR z)
    (x OR y) AND z = (x AND z) OR (y AND z)
    

The choice between different possible variants of the index_merge access method and other access methods is based on cost estimates of various available options.

Index Merge Intersection Access Algorithm

This access algorithm can be employed when a WHERE clause was converted to several range conditions on different keys combined with AND, and each condition is one of the following:

  • In this form, where the index has exactly N parts (that is, all index parts are covered):

    key_part1=const1 AND key_part2=const2 ... AND key_partN=constN
    
  • Any range condition over a primary key of an InnoDB or BDB table.

Here are some examples:

SELECT * FROM innodb_table WHERE primary_key < 10 AND key_col1=20;

SELECT * FROM tbl_name
WHERE (key1_part1=1 AND key1_part2=2) AND key2=2;

The Index Merge intersection algorithm performs simultaneous scans on all used indexes and produces the intersection of row sequences that it receives from the merged index scans.

If all columns used in the query are covered by the used indexes, full table records will not be retrieved (EXPLAIN output will contain Using index in Extra field in this case). Here is an example of such query:

SELECT COUNT(*) FROM t1 WHERE key1=1 AND key2=1;

If the used indexes don't cover all columns used in the query, full records will be retrieved only when the range conditions for all used keys are satisfied.

If one of the merged conditions is a condition over a primary key of an InnoDB or BDB table, it is not used for record retrieval, but is used to filter out records retrieved using other conditions.

Index Merge Union Access Algorithm

The applicability criteria for this algorithm are similar to those of the Index Merge method intersection algorithm. The algorithm can be employed when the table WHERE clause was converted to several range conditions on different keys combined with OR, and each condition is one of the following:

  • In this form, where the index has exactly N parts (that is, all index parts are covered):

    key_part1=const1 AND key_part2=const2 ... AND key_partN=constN
    
  • Any range condition over a primary key of an InnoDB or BDB table.

  • A condition for which the Index Merge method intersection algorithm is applicable.

Here are some examples:

SELECT * FROM t1 WHERE key1=1 OR key2=2 OR key3=3;

SELECT * FROM innodb_table WHERE (key1=1 AND key2=2) OR
  (key3='foo' AND key4='bar') AND key5=5;

Index Merge Sort-Union Access Algorithm

This access algorithm is employed when the WHERE clause was converted to several range conditions combined by OR, but for which the Index Merge method union algorithm is not applicable.

Here are some examples:

SELECT * FROM tbl_name WHERE key_col1 < 10 OR key_col2 < 20;

SELECT * FROM tbl_name
     WHERE (key_col1 > 10 OR key_col2 = 20) AND nonkey_col=30;

The difference between the sort-union algorithm and the union algorithm is that the sort-union algorithm must first fetch row IDs for all records and sort them before returning any records.

How MySQL Optimizes IS NULL

MySQL can do the same optimization on col_name IS NULL that it can do with col_name = constant_value. For example, MySQL can use indexes and ranges to search for NULL with IS NULL.

SELECT * FROM tbl_name WHERE key_col IS NULL;

SELECT * FROM tbl_name WHERE key_col <=> NULL;

SELECT * FROM tbl_name
    WHERE key_col=const1 OR key_col=const2 OR key_col IS NULL;

If a WHERE clause includes a col_name IS NULL condition for a column that is declared as NOT NULL, that expression will be 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 4.1.1 and up can additionally optimize the combination col_name = expr AND col_name IS NULL, a form that is common in resolved subqueries. EXPLAIN will show 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 will use key lookups only on the expression (t1.a=t2.a AND t2.a IS NULL) and not be 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);

How MySQL Optimizes DISTINCT

DISTINCT combined with ORDER BY will need a temporary table in many cases.

Note that because DISTINCT may use GROUP BY, you should be aware of how MySQL works with columns in ORDER BY or HAVING clauses that are not part of the selected columns. See the section called “GROUP BY with Hidden Fields”.

In most cases, a DISTINCT clause can be considered as a special case of GROUP BY. For example, the following two queries are equivalent:

SELECT DISTINCT(c1, c2, c3) FROM t1 WHERE c1 > const;

SELECT c1, c2, c3 FROM t1 WHERE c1 > const GROUP BY c1, c2, c3;

Due to this equivalence, the optimizations applicable to GROUP BY queries can be also applied to queries with a DISTINCT clause. Thus, for more details on the optimization possibilities for DISTINCT queries, see GROUP BY optimization.

When combining LIMIT row_count with DISTINCT, MySQL stops as soon as it finds row_count unique rows.

If you don't use columns from all tables named in a query, MySQL stops scanning the not-used tables as soon as it finds the first match. In the following case, assuming that t1 is used before t2 (which you can check with EXPLAIN), MySQL stops reading from t2 (for any particular row in t1) when the first row in t2 is found:

SELECT DISTINCT t1.a FROM t1, t2 where t1.a=t2.a;

How MySQL Optimizes LEFT JOIN and RIGHT JOIN

A LEFT JOIN B join_condition is implemented in MySQL as follows:

  • Table B is set to depend on table A and all tables on which A depends.

  • Table A is set to depend on all tables (except B) that are used in the LEFT JOIN condition.

  • The LEFT JOIN condition is used to decide how to retrieve rows from table B. (In other words, any condition in the WHERE clause is not used.)

  • All standard join optimizations are done, with the exception that a table is always read after all tables on which it depends. If there is a circular dependence, MySQL issues an error.

  • All standard WHERE optimizations are done.

  • If there is a row in A that matches the WHERE clause, but there is no row in B that matches the ON condition, an extra B row is generated with all columns set to NULL.

  • If you use LEFT JOIN to find rows that don't exist in some table and you have the following test: col_name IS NULL in the WHERE part, where col_name is a column that is declared as NOT NULL, MySQL stops searching for more rows (for a particular key combination) after it has found one row that matches the LEFT JOIN condition.

RIGHT JOIN is implemented analogously to LEFT JOIN, with the roles of the tables reversed.

The join optimizer calculates the order in which tables should be joined. The table read order forced by LEFT JOIN and STRAIGHT_JOIN helps the join optimizer do its work much more quickly, because there are fewer table permutations to check. Note that this means that if you do a query of the following type, MySQL will do a full scan on b because the LEFT JOIN forces it to be read before d:

SELECT *
    FROM a,b LEFT JOIN c ON (c.key=a.key) LEFT JOIN d ON (d.key=a.key)
    WHERE b.key=d.key;

The fix in this case is to rewrite the query as follows:

SELECT *
    FROM b,a LEFT JOIN c ON (c.key=a.key) LEFT JOIN d ON (d.key=a.key)
    WHERE b.key=d.key;

Starting from 4.0.14, MySQL does the following LEFT JOIN optimization: If the WHERE condition is always false for the generated NULL row, the LEFT JOIN is changed to a normal join.

For example, the WHERE clause would be false in the following query if t2.column1 would be NULL:

SELECT * FROM t1 LEFT JOIN t2 ON (column1) WHERE t2.column2=5;

Therefore, it's safe to convert the query to a normal join:

SELECT * FROM t1, t2 WHERE t2.column2=5 AND t1.column1=t2.column1;

This can be made faster because MySQL can now use table t2 before table t1 if this would result in a better query plan. To force a specific table order, use STRAIGHT_JOIN.

How MySQL Optimizes ORDER BY

In some cases, MySQL can use an index to satisfy an ORDER BY clause without doing any extra sorting.

The index can also be used even if the ORDER BY doesn't match the index exactly, as long as all the unused index parts and all the extra are ORDER BY columns are constants in the WHERE clause. The following queries will use the index to resolve the ORDER BY part:

SELECT * FROM t1 ORDER BY key_part1,key_part2,... ;
SELECT * FROM t1 WHERE key_part1=constant ORDER BY key_part2;
SELECT * FROM t1 ORDER BY key_part1 DESC, key_part2 DESC;
SELECT * FROM t1
    WHERE key_part1=1 ORDER BY key_part1 DESC, key_part2 DESC;

In some cases, MySQL cannot use indexes to resolve the ORDER BY, although it still will use indexes to find the rows that match the WHERE clause. These cases include the following:

  • You use ORDER BY on different keys:

    SELECT * FROM t1 ORDER BY key1, key2;
    
  • You use ORDER BY on non-consecutive key parts:

    SELECT * FROM t1 WHERE key2=constant ORDER BY key_part2;
    
  • You mix ASC and DESC:

    SELECT * FROM t1 ORDER BY key_part1 DESC, key_part2 ASC;
    
  • The key used to fetch the rows is not the same as the one used in the ORDER BY:

    SELECT * FROM t1 WHERE key2=constant ORDER BY key1;
    
  • You are joining many tables, and the columns in the ORDER BY are not all from the first non-constant table that is used to retrieve rows. (This is the first table in the EXPLAIN output that doesn't have a const join type.)

  • You have different ORDER BY and GROUP BY expressions.

  • The type of table index used doesn't store rows in order. For example, this is true for a HASH index in a HEAP table.

With EXPLAIN SELECT ... ORDER BY, you can check whether MySQL can use indexes to resolve the query. It cannot if you see Using filesort in the Extra column. See EXPLAIN.

In those cases where MySQL must sort the result, it uses the following filesort algorithm before MySQL 4.1:

  1. Read all rows according to key or by table scanning. Rows that don't match the WHERE clause are skipped.

  2. For each row, store a pair of values in a buffer (the sort key and the row pointer). The size of the buffer is the value of the sort_buffer_size system variable.

  3. When the buffer gets full, run a qsort (quicksort) on it and store the result in a temporary file. Save a pointer to the sorted block. (If all pairs fit into the sort buffer, no temporary file is created.)

  4. Repeat the preceding steps until all rows have been read.

  5. Do a multi-merge of up to MERGEBUFF (7) regions to one block in another temporary file. Repeat until all blocks from the first file are in the second file.

  6. Repeat the following until there are fewer than MERGEBUFF2 (15) blocks left.

  7. On the last multi-merge, only the pointer to the row (the last part of the sort key) is written to a result file.

  8. Read the rows in sorted order by using the row pointers in the result file. To optimize this, we read in a big block of row pointers, sort them, and use them to read the rows in sorted order into a row buffer. The size of the buffer is the value of the read_rnd_buffer_size system variable. The code for this step is in the sql/records.cc source file.

One problem with this approach is that it reads rows twice: One time when evaluating the WHERE clause, and again after sorting the pair values. And even if the rows were accessed successively the first time (for example, if a table scan is done), the second time they are accessed randomly. (The sort keys are ordered, but the row positions are not.)

In MySQL 4.1 and up, a filesort optimization is used that records not only the sort key value and row position, but also the columns required for the query. This avoids reading the rows twice. The modified filesort algorithm works like this:

  1. Read the rows that match the WHERE clause, as before.

  2. For each row, record a tuple of values consisting of the sort key value and row position, and also the columns required for the query.

  3. Sort the tuples by sort key value

  4. Retrieve the rows in sorted order, but read the required columns directly from the sorted tuples rather than by accessing the table a second time.

Using the modified filesort algorithm, the tuples are longer than the pairs used in the original method, and fewer of them fit in the sort buffer (the size of which is given by sort_buffer_size). As a result, it is possible for the extra I/O to make the modified approach slower, not faster. To avoid a slowdown, the optimization is used only if the total size of the extra columns in the sort tuple does not exceed the value of the max_length_for_sort_data system variable. (A symptom of setting the value of this variable too high is that you will see high disk activity and low CPU activity.)

If you want to increase ORDER BY speed, first see whether you can get MySQL to use indexes rather than an extra sorting phase. If this is not possible, you can try the following strategies:

  • Increase the size of the sort_buffer_size variable.

  • Increase the size of the read_rnd_buffer_size variable.

  • Change tmpdir to point to a dedicated filesystem with lots of empty space. If you use MySQL 4.1 or later, this option accepts several paths that are used in round-robin fashion. Paths should be separated by colon characters (‘:’) on Unix and semicolon characters (‘;’) on Windows, NetWare, and OS/2. You can use this feature to spread the load across several directories. Note: The paths should be for directories in filesystems that are located on different physical disks, not different partitions of the same disk.

By default, MySQL sorts all GROUP BY col1, col2, ... queries as if you specified ORDER BY col1, col2, ... in the query as well. If you include an ORDER BY clause explicitly that contains the same column list, MySQL optimizes it away without any speed penalty, although the sorting still occurs. If a query includes GROUP BY but you want to avoid the overhead of sorting the result, you can suppress sorting by specifying ORDER BY NULL. For example:

INSERT INTO foo
SELECT a, COUNT(*) FROM bar GROUP BY a ORDER BY NULL;

How MySQL Optimizes GROUP BY

The most general way to satisfy a GROUP BY clause is to scan the whole table and create a new temporary table where all rows from each group are consecutive, and then use this temporary table to discover groups and apply aggregate functions (if any). In some cases, MySQL is able to do much better than that and to avoid creation of temporary tables by using index access.

The most important preconditions for using indexes for GROUP BY are that all GROUP BY columns reference attributes from the same index, and the index stores its keys in order (for example, this is a B-Tree index, and not a HASH index). Whether usage of temporary tables can be replaced by index access also depends on which parts of an index are used in a query, the conditions specified for these parts, and the selected aggregate functions.

There are two ways to execute a GROUP BY query via index access, as detailed in the following sections. In the first method, the grouping operation is applied together with all range predicates (if any). The second method first performs a range scan, and then groups the resulting tuples.

Loose index scan

The most efficient way is when the index is used to directly retrieve the group fields. With this access method, MySQL uses the property of some index types (for example, B-Trees) that the keys are ordered. This property allows use of lookup groups in an index without having to consider all keys in the index that satisfy all WHERE conditions. Since this access method considers only a fraction of the keys in an index, it is called “loose index scan.” When there is no WHERE clause, a loose index scan will read as many keys as the number of groups, which may be a much smaller number than all keys. If the WHERE clause contains range predicates (described in EXPLAIN, under the range join type), a loose index scan looks up the first key of each group that satisfies the range conditions, and again reads the least possible number of keys. This is possible under the following conditions:

  • The query is over a single table.

  • The GROUP BY includes the first consecutive parts of the index (if instead of GROUP BY, the query has a DISTINCT clause, then all distinct attributes refer to the beginning of the index).

  • The only aggregate functions used (if any) are MIN() and MAX(), and all of them refer to the same column.

  • Any other index parts than the ones from GROUP BY referenced in the query must be constants (that is, they must be referenced in equalities with constants), except for the argument of MIN() or MAX() functions.

The EXPLAIN output for such queries shows Using index for group-by in the Extra column.

The following queries provide several examples that fall into this category, assuming there is an index idx(c1, c2, c3) on table t1(c1,c2,c3,c4):

SELECT c1, c2 FROM t1 GROUP BY c1, c2;
SELECT DISTINCT(c1, c2) FROM t1;
SELECT c1, MIN(c2) FROM t1 GROUP BY c1;
SELECT c1, c2 FROM t1 WHERE c1 < const GROUP BY c1, c2;
SELECT MAX(c3), MIN(c3), c1, c2 FROM t1 WHERE c2 > const GROUP BY c1, c2;
SELECT c2 FROM t1 WHERE c1 < const GROUP BY c1, c2;
SELECT c1, c2 FROM t1 WHERE c3 = const GROUP BY c1, c2;

The following queries cannot be executed with this quick select method, for the reasons given:

  • There are other aggregate function than MIN() or MAX():

    SELECT c1, SUM(c2) FROM t1 GROUP BY c1;
    
  • The fields in GROUP BY do not refer to the beginning of the index:

    SELECT c1,c2 FROM t1 GROUP BY c2, c3;
    
  • The query refers to a key part that is after the GROUP BY parts, and for which there is no equality with a constant:

    SELECT c1,c3 FROM t1 GROUP BY c1, c2;
    

Tight index scan

A tight index scan may be either a full index scan or a range index scan, depending on the query conditions.

When the conditions for a loose index scan are not met, it is still possible to avoid creation of temporary tables for GROUP BY queries. If there are range conditions in the WHERE clause, this method will read only the keys that satisfy these conditions. Otherwise, it performs an index scan. Since this method reads all keys in each range defined by the WHERE clause, or scans the whole index if there are no range conditions, we term it a “tight index scan.” Notice that with a tight index scan, the grouping operation is performed after all keys that satisfy the range conditions have been found.

For this method to work, it is sufficient that for all columns in a query referring to key parts before or in between the GROUP BY key parts, there is a constant equality condition. The constants from the equality conditions fill in the “gaps” in the search keys so that it is possible to form complete prefixes of the index. Then these index prefixes can be used for index lookups. If we require sorting of the GROUP BY result, and it is possible to form search keys that are prefixes of the index, MySQL also will avoid sorting because searching with prefixes in an ordered index already retrieves all keys in order.

The following queries will not work with the first method above, but will still work with the second index access method (assuming we have the aforementioned index idx on table t1):

  • There is a “gap” in GROUP BY, but it is covered by the condition (c2 = 'a').

    SELECT c1, c2, c3 FROM t1 WHERE c2 = 'a' GROUP BY c1, c3;
    
  • GROUP BY does not begin from the first key part, but there is a condition that provides a constant for that key part:

    SELECT c1, c2, c3 FROM t1 WHERE c1 = 'a' GROUP BY c2, c3;
    

How MySQL Optimizes LIMIT

In some cases, MySQL will handle a query differently when you are using LIMIT row_count and not using HAVING:

  • If you are selecting only a few rows with LIMIT, MySQL uses indexes in some cases when normally it would prefer to do a full table scan.

  • If you use LIMIT row_count with ORDER BY, MySQL ends the sorting as soon as it has found the first row_count lines rather than sorting the whole table.

  • When combining LIMIT row_count with DISTINCT, MySQL stops as soon as it finds row_count unique rows.

  • In some cases, a GROUP BY can be resolved by reading the key in order (or doing a sort on the key) and then calculating summaries until the key value changes. In this case, LIMIT row_count will not calculate any unnecessary GROUP BY values.

  • As soon as MySQL has sent the required number of rows to the client, it aborts the query unless you are using SQL_CALC_FOUND_ROWS.

  • LIMIT 0 always quickly returns an empty set. This is useful to check the query or to get the column types of the result columns.

  • When the server uses temporary tables to resolve the query, the LIMIT row_count is used to calculate how much space is required.

How to Avoid Table Scans

The output from EXPLAIN will show ALL in the type column when MySQL uses a table scan to resolve a query. This usually happens under the following conditions:

  • The table is so small that it's faster to do a table scan than a key lookup. This is a common case for tables with fewer than 10 rows and a short row length.

  • There are no usable restrictions in the ON or WHERE clause for indexed columns.

  • You are comparing indexed columns with constant values and MySQL has calculated (based on the index tree) that the constants cover too large a part of the table and that a table scan would be faster. See the section called “How MySQL Optimizes WHERE Clauses”.

  • You are using a key with low cardinality (many rows match the key value) through another column. In this case, MySQL assumes that by using the key it will probably do a lot of key lookups and that a table scan would be faster.

For small tables, a table scan often is appropriate. For large tables, try the following techniques to avoid having the optimizer incorrectly choose a table scan:

  • Use ANALYZE TABLE tbl_name to update the key distributions for the scanned table. See ANALYZE TABLE.

  • Use FORCE INDEX for the scanned table to tell MySQL that table scans are very expensive compared to using the given index. See SELECT.

    SELECT * FROM t1, t2 FORCE INDEX (index_for_column)
    WHERE t1.col_name=t2.col_name;
    
  • Start mysqld with the --max-seeks-for-key=1000 option or use SET max_seeks_for_key=1000 to tell the optimizer to assume that no key scan will cause more than 1,000 key seeks. See the section called “Server System Variables”.

Speed of INSERT Statements

The time to insert a record is determined by the following factors, where the numbers indicate approximate proportions:

  • Connecting: (3)

  • Sending query to server: (2)

  • Parsing query: (2)

  • Inserting record: (1 x size of record)

  • Inserting indexes: (1 x number of indexes)

  • Closing: (1)

This does not take into consideration the initial overhead to open tables, which is done once for each concurrently running query.

The size of the table slows down the insertion of indexes by log N, assuming B-tree indexes.

You can use the following methods to speed up inserts:

  • If you are inserting many rows from the same client at the same time, use INSERT statements with multiple VALUES lists to insert several rows at a time. This is much faster (many times faster in some cases) than using separate single-row INSERT statements. If you are adding data to a non-empty table, you may tune the bulk_insert_buffer_size variable to make it even faster. See the section called “Server System Variables”.

  • If you are inserting a lot of rows from different clients, you can get higher speed by using the INSERT DELAYED statement. See INSERT.

  • With MyISAM tables you can insert rows at the same time that SELECT statements are running if there are no deleted rows in the tables.

  • When loading a table from a text file, use LOAD DATA INFILE. This is usually 20 times faster than using a lot of INSERT statements. See LOAD DATA.

  • With some extra work, it is possible to make LOAD DATA INFILE run even faster when the table has many indexes. Use the following procedure:

    1. Optionally create the table with CREATE TABLE.

    2. Execute a FLUSH TABLES statement or a mysqladmin flush-tables command.

    3. Use myisamchk --keys-used=0 -rq /path/to/db/tbl_name. This will remove all use of all indexes for the table.

    4. Insert data into the table with LOAD DATA INFILE. This will not update any indexes and will therefore be very fast.

    5. If you are going to only read the table in the future, use myisampack to make it smaller. See the section called “Compressed Table Characteristics”.

    6. Re-create the indexes with myisamchk -r -q /path/to/db/tbl_name. This will create the index tree in memory before writing it to disk, which is much faster because it avoids lots of disk seeks. The resulting index tree is also perfectly balanced.

    7. Execute a FLUSH TABLES statement or a mysqladmin flush-tables command.

    Note that LOAD DATA INFILE also performs the preceding optimization if you insert into an empty MyISAM table; the main difference is that you can let myisamchk allocate much more temporary memory for the index creation than you might want the server to allocate for index re-creation when it executes the LOAD DATA INFILE statement.

    As of MySQL 4.0, you can also use ALTER TABLE tbl_name DISABLE KEYS instead of myisamchk --keys-used=0 -rq /path/to/db/tbl_name and ALTER TABLE tbl_name ENABLE KEYS instead of myisamchk -r -q /path/to/db/tbl_name. This way you can also skip the FLUSH TABLES steps.

  • You can speed up INSERT operations that are done with multiple statements by locking your tables:

    LOCK TABLES a WRITE;
    INSERT INTO a VALUES (1,23),(2,34),(4,33);
    INSERT INTO a VALUES (8,26),(6,29);
    UNLOCK TABLES;
    

    A performance benefit occurs because the index buffer is flushed to disk only onc, after all INSERT statements have completed. Normally there would be as many index buffer flushes as there are different INSERT statements. Explicit locking statements are not needed if you can insert all rows with a single statement.

    For transactional tables, you should use BEGIN/COMMIT instead of LOCK TABLES to get a speedup.

    Locking also lowers the total time of multiple-connection tests, although the maximum wait time for individual connections might go up because they wait for locks. For example:

    Connection 1 does 1000 inserts
    Connections 2, 3, and 4 do 1 insert
    Connection 5 does 1000 inserts
    

    If you don't use locking, connections 2, 3, and 4 will finish before 1 and 5. If you use locking, connections 2, 3, and 4 probably will not finish before 1 or 5, but the total time should be about 40% faster.

    INSERT, UPDATE, and DELETE operations are very fast in MySQL, but you will obtain better overall performance by adding locks around everything that does more than about five inserts or updates in a row. If you do very many inserts in a row, you could do a LOCK TABLES followed by an UNLOCK TABLES once in a while (about each 1,000 rows) to allow other threads access to the table. This would still result in a nice performance gain.

    INSERT is still much slower for loading data than LOAD DATA INFILE, even when using the strategies just outlined.

  • To get some more speed for MyISAM tables, for both LOAD DATA INFILE and INSERT, enlarge the key cache by increasing the key_buffer_size system variable. See the section called “Tuning Server Parameters”.

Speed of UPDATE Statements

Update statements are optimized as a SELECT query with the additional overhead of a write. The speed of the write depends on the amount of data being updated and the number of indexes that are updated. Indexes that are not changed will not be updated.

Also, another way to get fast updates is to delay updates and then do many updates in a row later. Doing many updates in a row is much quicker than doing one at a time if you lock the table.

Note that for a MyISAM table that uses dynamic record format, updating a record to a longer total length may split the record. If you do this often, it is very important to use OPTIMIZE TABLE occasionally. See OPTIMIZE TABLE.

Speed of DELETE Statements

The time to delete individual records is exactly proportional to the number of indexes. To delete records more quickly, you can increase the size of the key cache. See the section called “Tuning Server Parameters”.

If you want to delete all rows in the table, use TRUNCATE TABLE tbl_name rather than DELETE FROM tbl_name. See TRUNCATE.

Other Optimization Tips

This section lists a number of miscellaneous tips for improving query processing speed:

  • Use persistent connections to the database to avoid connection overhead. If you can't use persistent connections and you are initiating many new connections to the database, you may want to change the value of the thread_cache_size variable. See the section called “Tuning Server Parameters”.

  • Always check whether all your queries really use the indexes you have created in the tables. In MySQL, you can do this with the EXPLAIN statement. See EXPLAIN.

  • Try to avoid complex SELECT queries on MyISAM tables that are updated frequently, to avoid problems with table locking that occur due to contention between readers and writers.

  • With MyISAM tables that have no deleted rows, you can insert rows at the end at the same time that another query is reading from the table. If this is important for you, you should consider using the table in ways that avoid deleting rows. Another possibility is to run OPTIMIZE TABLE after you have deleted a lot of rows.

  • Use ALTER TABLE ... ORDER BY expr1, expr2, ... if you mostly retrieve rows in expr1, expr2, ... order. By using this option after extensive changes to the table, you may be able to get higher performance.

  • In some cases, it may make sense to introduce a column that is “hashed” based on information from other columns. If this column is short and reasonably unique, it may be much faster than a big index on many columns. In MySQL, it's very easy to use this extra column:

    SELECT * FROM tbl_name
        WHERE hash_col=MD5(CONCAT(col1,col2))
        AND col1='constant' AND col2='constant';
    
  • For MyISAM tables that change a lot, you should try to avoid all variable-length columns (VARCHAR, BLOB, and TEXT). The table will use dynamic record format if it includes even a single variable-length column. See Chapter 15, MySQL Storage Engines and Table Types.

  • It's normally not useful to split a table into different tables just because the rows get “big.” To access a row, the biggest performance hit is the disk seek to find the first byte of the row. After finding the data, most modern disks can read the whole row fast enough for most applications. The only cases where it really matters to split up a table is if it's a MyISAM table with dynamic record format (see above) that you can change to a fixed record size, or if you very often need to scan the table but do not need most of the columns. See Chapter 15, MySQL Storage Engines and Table Types.

  • If you very often need to calculate results such as counts based on information from a lot of rows, it's probably much better to introduce a new table and update the counter in real time. An update of the following form is very fast:

    UPDATE tbl_name SET count_col=count_col+1 WHERE key_col=constant;
    

    This is really important when you use MySQL storage engines such as MyISAM and ISAM that have only table-level locking (multiple readers / single writers). This will also give better performance with most databases, because the row locking manager in this case will have less to do.

  • If you need to collect statistics from large log tables, use summary tables instead of scanning the entire log table. Maintaining the summaries should be much faster than trying to calculate statistics “live.” It's much faster to regenerate new summary tables from the logs when things change (depending on business decisions) than to have to change the running application!

  • If possible, you should classify reports as “live” or “statistical,” where data needed for statistical reports is created only from summary tables that are generated periodically from the live data.

  • Take advantage of the fact that columns have default values. Insert values explicitly only when the value to be inserted differs from the default. This reduces the parsing that MySQL needs to do and improves the insert speed.

  • In some cases, it's convenient to pack and store data into a BLOB column. In this case, you must add some extra code in your application to pack and unpack information in the BLOB values, but this may save a lot of accesses at some stage. This is practical when you have data that doesn't conform to a rows-and-columns table structure.

  • Normally, you should try to keep all data non-redundant (what is called "third normal form" in database theory). However, do not be afraid to duplicate information or create summary tables if necessary to gain more speed.

  • Stored procedures or UDFs (user-defined functions) may be a good way to get more performance for some tasks. However, if you use a database system that does not support these capabilities, you should always have another way to perform the same tasks, even if the alternative method is slower.

  • You can always gain something by caching queries or answers in your application and then performing many inserts or updates together. If your database supports table locks (like MySQL and Oracle), this should help to ensure that the index cache is only flushed once after all updates.

  • Use INSERT DELAYED when you do not need to know when your data is written. This speeds things up because many records can be written with a single disk write.

  • Use INSERT LOW_PRIORITY when you want to give SELECT statements higher priority than your inserts.

  • Use SELECT HIGH_PRIORITY to get retrievals that jump the queue. That is, the SELECT is done even if there is another client waiting to do a write.

  • Use multiple-row INSERT statements to store many rows with one SQL statement (many SQL servers support this).

  • Use LOAD DATA INFILE to load large amounts of data. This is faster than using INSERT statements.

  • Use AUTO_INCREMENT columns to generate unique values.

  • Use OPTIMIZE TABLE once in a while to avoid fragmentation with MyISAM tables when using a dynamic table format. See MyISAM table formats.

  • Use HEAP tables when possible to get more speed. See Chapter 15, MySQL Storage Engines and Table Types.

  • When using a normal Web server setup, images should be stored as files. That is, store only a file reference in the database. The main reason for this is that a normal Web server is much better at caching files than database contents, so it's much easier to get a fast system if you are using files.

  • Use in-memory tables for non-critical data that is accessed often, such as information about the last displayed banner for users who don't have cookies enabled in their Web browser.

  • Columns with identical information in different tables should be declared to have identical data types. Before MySQL 3.23, you get slow joins otherwise.

    Try to keep column names simple. For example, in a table named customer, use a column name of name instead of customer_name. To make your names portable to other SQL servers, you should keep them shorter than 18 characters.

  • If you need really high speed, you should take a look at the low-level interfaces for data storage that the different SQL servers support! For example, by accessing the MySQL MyISAM storage engine directly, you could get a speed increase of two to five times compared to using the SQL interface. To be able to do this, the data must be on the same server as the application, and usually it should only be accessed by one process (because external file locking is really slow). One could eliminate these problems by introducing low-level MyISAM commands in the MySQL server (this could be one easy way to get more performance if needed). By carefully designing the database interface, it should be quite easy to support this types of optimization.

  • If you are using numerical data, it's faster in many cases to access information from a database (using a live connection) than to access a text file. Information in the database is likely to be stored in a more compact format than in the text file, so accessing it will involve fewer disk accesses. You will also save code in your application because you don't have to parse your text files to find line and column boundaries.

  • Replication can provide a performance benefit for some operations. You can distribute client retrievals among replication servers to split up the load. To avoid slowing down the master while making backups, you can make backups using a slave server. See Chapter 6, Replication in MySQL.

  • Declaring a MyISAM table with the DELAY_KEY_WRITE=1 table option makes index updates faster because they are not flushed to disk until the table is closed. The downside is that if something kills the server while such a table is open, you should ensure that they are okay by running the server with the --myisam-recover option, or by running myisamchk before restarting the server. (However, even in this case, you should not lose anything by using DELAY_KEY_WRITE, because the key information can always be generated from the data rows.)