The EXPLAIN statement produces
extra (“extended”) information that is not part of
EXPLAIN output but can be viewed
by issuing a SHOW WARNINGS
statement following EXPLAIN. As
of MySQL 8.0.12, extended information is available for
SELECT,
DELETE,
INSERT,
REPLACE, and
UPDATE statements. Prior to
8.0.12, extended information is available only for
SELECT statements.
The Message value in
SHOW WARNINGS output 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.
The extended information displayable with a
SHOW WARNINGS statement following
EXPLAIN is produced only for
SELECT statements.
SHOW WARNINGS displays an empty
result for other explainable statements
(DELETE,
INSERT,
REPLACE, and
UPDATE).
Here is an example of extended
EXPLAIN output:
mysql> EXPLAIN
SELECT t1.a, t1.a IN (SELECT t2.a FROM t2) FROM t1\G
*************************** 1. row ***************************
id: 1
select_type: PRIMARY
table: t1
type: index
possible_keys: NULL
key: PRIMARY
key_len: 4
ref: NULL
rows: 4
filtered: 100.00
Extra: Using index
*************************** 2. row ***************************
id: 2
select_type: SUBQUERY
table: t2
type: index
possible_keys: a
key: a
key_len: 5
ref: NULL
rows: 3
filtered: 100.00
Extra: Using index
2 rows in set, 1 warning (0.00 sec)
mysql> SHOW WARNINGS\G
*************************** 1. row ***************************
Level: Note
Code: 1003
Message: /* select#1 */ select `test`.`t1`.`a` AS `a`,
<in_optimizer>(`test`.`t1`.`a`,`test`.`t1`.`a` in
( <materialize> (/* select#2 */ select `test`.`t2`.`a`
from `test`.`t2` where 1 having 1 ),
<primary_index_lookup>(`test`.`t1`.`a` in
<temporary table> on <auto_key>
where ((`test`.`t1`.`a` = `materialized-subquery`.`a`))))) AS `t1.a
IN (SELECT t2.a FROM t2)` from `test`.`t1`
1 row in set (0.00 sec)
Because the statement displayed by SHOW
WARNINGS may contain special markers to provide
information about query rewriting or optimizer actions, the
statement is not necessarily valid SQL and is not intended to be
executed. The output may also include rows with
Message values that provide additional
non-SQL explanatory notes about actions taken by the optimizer.
The following list describes special markers that can appear in
the extended output displayed by SHOW
WARNINGS:
<auto_key>An automatically generated key for a temporary table.
<cache>(expr)The expression (such as a scalar subquery) is executed once and the resulting value is saved in memory for later use. For results consisting of multiple values, a temporary table may be created and
<temporary table>is shown instead.<exists>(query fragment)The subquery predicate is converted to an
EXISTSpredicate and the subquery is transformed so that it can be used together with theEXISTSpredicate.<in_optimizer>(query fragment)This is an internal optimizer object with no user significance.
<index_lookup>(query fragment)The query fragment is processed using an index lookup to find qualifying rows.
<if>(condition,expr1,expr2)If the condition is true, evaluate to
expr1, otherwiseexpr2.<is_not_null_test>(expr)A test to verify that the expression does not evaluate to
NULL.<materialize>(query fragment)Subquery materialization is used.
`materialized-subquery`.col_nameA reference to the column
col_namein an internal temporary table materialized to hold the result from evaluating a subquery.<primary_index_lookup>(query fragment)The query fragment is processed using a primary key lookup to find qualifying rows.
<ref_null_helper>(expr)This is an internal optimizer object with no user significance.
/* select#N*/select_stmtThe
SELECTis associated with the row in non-extendedEXPLAINoutput that has anidvalue ofN.outer_tablessemi join (inner_tables)A semijoin operation.
inner_tablesshows the tables that were not pulled out. See Section 10.2.2.1, “Optimizing IN and EXISTS Subquery Predicates with Semijoin Transformations”.<temporary table>This represents an internal temporary table created to cache an intermediate result.
When some tables are of const
or system type, expressions
involving columns from these tables are evaluated early by the
optimizer and are not part of the displayed statement. However,
with FORMAT=JSON, some
const table accesses are
displayed as a ref access
that uses a const value.