The EXPLAIN
statement can be used
either as a synonym for DESCRIBE
or as a way to obtain information about how MySQL executes a
SELECT
statement:
EXPLAIN
is synonymous
with tbl_name
DESCRIBE
or
tbl_name
SHOW COLUMNS FROM
:
tbl_name
EXPLAIN tbl_name
When you precede a SELECT
statement with the keyword
EXPLAIN
, MySQL displays
information from the optimizer about the query execution
plan. That is, MySQL explains how it would process the
SELECT
, including information
about how tables are joined and in which order:
EXPLAIN [EXTENDED] SELECT select_options
This section describes the second use of
EXPLAIN
for obtaining query
execution plan information. See also Section 12.8.2, “EXPLAIN
Syntax”.
For a description of the DESCRIBE
and SHOW COLUMNS
statements, see
Section 12.8.1, “DESCRIBE
Syntax”, and Section 12.4.5.5, “SHOW COLUMNS
Syntax”.
With the help of EXPLAIN
, you can
see where you should add indexes to tables to get a faster
SELECT
that uses indexes to find
rows. You can also use EXPLAIN
to
check whether the optimizer joins the tables in an optimal
order. To give a hint to 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
. (See
Section 12.2.8, “SELECT
Syntax”.)
If you have a problem with indexes not being used when you
believe that they should be, you should run
ANALYZE TABLE
to update table
statistics such as cardinality of keys, that can affect the
choices the optimizer makes. See
Section 12.4.2.1, “ANALYZE TABLE
Syntax”.
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
nested-loop join method. This means that MySQL reads a row from
the first table, and then finds a matching row in the second
table, the third table, and so on. When all tables are
processed, MySQL 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.
When the EXTENDED
keyword is used,
EXPLAIN
produces extra
information that can be viewed by issuing a
SHOW WARNINGS
statement following
the EXPLAIN
statement. This
information displays how the optimizer qualifies table and
column names in the SELECT
statement, what the SELECT
looks
like after the application of rewriting and optimization rules,
and possibly other notes about the optimization process.
Each output row from EXPLAIN
provides information about one table, and each row contains 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 those shown in the following table.
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 query |
UNION RESULT |
Result of a UNION . |
SUBQUERY |
First SELECT in subquery |
DEPENDENT SUBQUERY |
First SELECT in subquery, dependent on
outer query |
DERIVED |
Derived table SELECT (subquery in
FROM clause) |
UNCACHEABLE SUBQUERY |
A subquery for which the result cannot be cached and must be re-evaluated for each row of the outer query |
DEPENDENT
typically signifies the use of
a correlated subquery. See
Section 12.2.9.7, “Correlated Subqueries”.
“DEPENDENT SUBQUERY” evaluation differs from
UNCACHEABLE SUBQUERY
evaluation. For
“DEPENDENT SUBQUERY”, the subquery is
re-evaluated only once for each set of different values of
the variables from its outer context. For
UNCACHEABLE SUBQUERY
, the subquery is
re-evaluated for each row of the outer context. Cacheability
of subqueries is subject to the restrictions detailed in
Section 7.5.5.1, “How the Query Cache Operates”. For example,
referring to user variables makes a subquery uncacheable.
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:
The table has only one row (= system table). This is a
special case of the
const
join type.
The table has at most one matching row, which is 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 to
constant values. In the following queries,
tbl_name
can be used as a
const
table:
SELECT * FROMtbl_name
WHEREprimary_key
=1; SELECT * FROMtbl_name
WHEREprimary_key_part1
=1 ANDprimary_key_part2
=2;
One row is read from this table for each combination of
rows from the previous tables. Other than the
system
and
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 * FROMref_table
,other_table
WHEREref_table
.key_column
=other_table
.column
; SELECT * FROMref_table
,other_table
WHEREref_table
.key_column_part1
=other_table
.column
ANDref_table
.key_column_part2
=1;
All rows with matching index values are 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
=
or <=>
operator. In the following examples, MySQL can use a
ref
join to process
ref_table
:
SELECT * FROMref_table
WHEREkey_column
=expr
; SELECT * FROMref_table
,other_table
WHEREref_table
.key_column
=other_table
.column
; SELECT * FROMref_table
,other_table
WHEREref_table
.key_column_part1
=other_table
.column
ANDref_table
.key_column_part2
=1;
The join is performed using a
FULLTEXT
index.
This join type is like
ref
, but with the
addition that MySQL does an extra search for rows that
contain NULL
values. This join type
optimization is used most often in resolving subqueries.
In the following examples, MySQL can use a
ref_or_null
join to
process ref_table
:
SELECT * FROMref_table
WHEREkey_column
=expr
ORkey_column
IS NULL;
This join type indicates that the Index Merge
optimization is used. In this case, the
key
column in the output row 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
Section 7.2.6, “Index Merge Optimization”.
This type replaces
ref
for some
IN
subqueries of the following form:
value
IN (SELECTprimary_key
FROMsingle_table
WHEREsome_expr
)
unique_subquery
is
just an index lookup function that replaces the subquery
completely for better efficiency.
This join type is similar to
unique_subquery
. It
replaces IN
subqueries, but it works
for nonunique indexes in subqueries of the following
form:
value
IN (SELECTkey_column
FROMsingle_table
WHEREsome_expr
)
Only rows that are in a given range are retrieved, using
an index to select the rows. The key
column in the output row indicates which index is used.
The key_len
contains the longest key
part that was used. The ref
column is
NULL
for this type.
range
can be used
when a key column is compared to a constant using any of
the =
,
<>
,
>
,
>=
,
<
,
<=
,
IS NULL
,
<=>
,
BETWEEN
, or
IN()
operators:
SELECT * FROMtbl_name
WHEREkey_column
= 10; SELECT * FROMtbl_name
WHEREkey_column
BETWEEN 10 and 20; SELECT * FROMtbl_name
WHEREkey_column
IN (10,20,30); SELECT * FROMtbl_name
WHEREkey_part1
= 10 ANDkey_part2
IN (10,20,30);
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.
A full table scan is 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 can choose from 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 check 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
Section 12.1.4, “ALTER TABLE
Syntax”.
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. If MySQL decides to use
one of the possible_keys
indexes to look
up rows, that index is listed as the key value.
It is possible that key
will name an
index that is not present in the
possible_keys
value. This can happen if
none of the possible_keys
indexes are
suitable for looking up rows, but all the columns selected
by the query are columns of some other index. That is, the
named index covers the selected columns, so although it is
not used to determine which rows to retrieve, an index scan
is more efficient than a data row scan.
For InnoDB
, a secondary index might cover
the selected columns even if the query also selects the
primary key because InnoDB
stores the
primary key value with each secondary index. If
key
is NULL
, MySQL
found no index to use for executing the query more
efficiently.
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
Section 12.2.8.2, “Index Hint Syntax”.
For MyISAM
and BDB
tables, running ANALYZE TABLE
helps the optimizer choose better indexes. For
MyISAM
tables, myisamchk
--analyze does the same. See
Section 12.4.2.1, “ANALYZE TABLE
Syntax”, and
Section 6.6, “MyISAM
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
enables you to determine how many
parts of a multiple-part key MySQL actually uses.
ref
The ref
column shows which columns or
constants are compared to the index named in the
key
column to select rows from the table.
rows
The rows
column indicates the number of
rows MySQL believes it must examine to execute the query.
For InnoDB
tables, this number
is an estimate, and may not always be exact.
Extra
This column contains additional information about how MySQL
resolves the query. The following list explains the values
that can appear in this column. If you want to make your
queries as fast as possible, you should look out for
Extra
values of Using
filesort
and Using temporary
.
const row not found
For a query such as SELECT ... FROM
, the table
was empty.
tbl_name
Distinct
MySQL is looking for distinct values, so it stops searching for more rows for the current row combination after it has found the first matching row.
Full scan on NULL key
This occurs for subquery optimization as a fallback strategy when the optimizer cannot use an index-lookup access method.
Impossible HAVING
The HAVING
clause is always false and
cannot select any rows.
Impossible WHERE
The WHERE
clause is always false and
cannot select any rows.
Impossible WHERE noticed after reading const
tables
MySQL has read all
const
(and
system
) tables and
notice that the WHERE
clause is
always false.
No matching min/max row
No row satisfies the condition for a query such as
SELECT MIN(...) FROM ... WHERE
.
condition
no matching row in const table
For a query with a join, there was an empty table or a table with no rows satisfying a unique index condition.
No tables used
The query has no FROM
clause, or has
a FROM DUAL
clause.
Not exists
MySQL was able to do a LEFT JOIN
optimization on the query and does 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 scans
t1
and looks 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 does 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:
N
)
MySQL found no good index to use, but found that some of
indexes might be used after column values from preceding
tables are known. For each row combination in the
preceding tables, MySQL checks whether it is possible to
use a range
or
index_merge
access
method to retrieve rows. This is not very fast, but is
faster than performing a join with no index at all. The
applicability criteria are as described in
Section 7.2.5, “Range Optimization”, and
Section 7.2.6, “Index Merge Optimization”, with the
exception that all column values for the preceding table
are known and considered to be constants.
Indexes are numbered beginning with 1, in the same order
as shown by SHOW INDEX
for the table. The index map value
N
is a bitmask value that
indicates which indexes are candidates. For example, a
value of 0x19
(binary 11001) means
that indexes 1, 4, and 5 will be considered.
Select tables optimized away
The query contained only aggregate functions
(MIN()
,
MAX()
) that were all
resolved using an index, or
COUNT(*)
for
MyISAM
, and no GROUP
BY
clause. The optimizer determined that only
one row should be returned.
unique row not found
For a query such as SELECT ... FROM
, no rows
satisfy the condition for a tbl_name
UNIQUE
index or PRIMARY KEY
on the table.
Using filesort
MySQL must 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 Section 7.2.13, “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 index for group-by
Similar to the Using index
table
access method, 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 is
used in the most efficient way so that for each group,
only a few index entries are read. For details, see
Section 7.2.14, “GROUP BY
Optimization”.
Using sort_union(...)
, Using
union(...)
, Using
intersect(...)
These indicate how index scans are merged for the
index_merge
join
type. See Section 7.2.6, “Index Merge Optimization”.
Using temporary
To resolve the query, MySQL needs 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 is 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
.
Using where with pushed condition
This item applies to
NDBCLUSTER
tables
only. It means that MySQL Cluster
is using the Condition Pushdown optimization to improve
the efficiency of a direct comparison between a
nonindexed column and a constant. In such cases, the
condition is “pushed down” to the cluster's
data nodes and is evaluated on all data nodes
simultaneously. This eliminates the need to send
nonmatching rows over the network, and can speed up such
queries by a factor of 5 to 10 times over cases where
Condition Pushdown could be but is not used. For more
information, see
Section 7.2.7, “Condition Pushdown 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 row product also is used to determine which multiple-table
SELECT
statements to execute and
which to abort. See Section 7.5.3, “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 that 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.
Table | Column | Data Type |
tt |
ActualPC |
CHAR(10) |
tt |
AssignedPC |
CHAR(10) |
tt |
ClientID |
CHAR(10) |
et |
EMPLOYID |
CHAR(15) |
do |
CUSTNMBR |
CHAR(15) |
The tables have the following indexes.
Table | Index |
tt |
ActualPC |
tt |
AssignedPC |
tt |
ClientID |
et |
EMPLOYID (primary key) |
do |
CUSTNMBR (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 (index map: 0x23)
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 takes
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 as the same type and size. In
this context, VARCHAR
and
CHAR
are considered the same if
they are declared as the same size.
tt.ActualPC
is declared as
CHAR(10)
and et.EMPLOYID
is CHAR(15)
, so 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 (index map: 0x1) et_1 ALL PRIMARY NULL NULL NULL 74 Range checked for each record (index map: 0x1) et eq_ref PRIMARY PRIMARY 15 tt.ActualPC 1
This is not perfect, but is much better: The product of the
rows
values is less by a factor of 74. This
version executes 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);
After that modification, 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
At this point, the query is optimized almost as well as
possible. 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;
With the additional index information, 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 by comparing the
rows
product with the actual number of rows
that the query returns. If the numbers are quite different, you
might 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.
It is possible in some cases to execute statements that modify
data when EXPLAIN
SELECT
is used with a subquery; for more information,
see Section 12.2.9.8, “Subqueries in the FROM
clause”.
MySQL Enterprise. Subscribers to the MySQL Enterprise Monitor regularly receive expert advice on optimization. For more information, see http://www.mysql.com/products/enterprise/advisors.html.
User Comments
Add your own comment.