Documentation Home
MySQL 9.0 Reference Manual
Related Documentation Download this Manual
PDF (US Ltr) - 40.0Mb
PDF (A4) - 40.1Mb
Man Pages (TGZ) - 258.8Kb
Man Pages (Zip) - 365.9Kb
Info (Gzip) - 4.0Mb
Info (Zip) - 4.0Mb


MySQL 9.0 Reference Manual  /  ...  /  EXPLAIN Statement

15.8.2 EXPLAIN Statement

{EXPLAIN | DESCRIBE | DESC}
    tbl_name [col_name | wild]

{EXPLAIN | DESCRIBE | DESC}
    [explain_type] [INTO variable]
    {[schema_spec] explainable_stmt | FOR CONNECTION connection_id}

{EXPLAIN | DESCRIBE | DESC} ANALYZE [FORMAT = TREE] [schema_spec] select_statement

{EXPLAIN | DESCRIBE | DESC} ANALYZE FORMAT = JSON INTO variable [schema_spec] select_statement

explain_type: {
    FORMAT = format_name
}

format_name: {
    TRADITIONAL
  | JSON
  | TREE
}

explainable_stmt: {
    SELECT statement
  | TABLE statement
  | DELETE statement
  | INSERT statement
  | REPLACE statement
  | UPDATE statement
}

schema_spec:
FOR {SCHEMA | DATABASE} schema_name

The DESCRIBE and EXPLAIN statements are synonyms. In practice, the DESCRIBE keyword is more often used to obtain information about table structure, whereas EXPLAIN is used to obtain a query execution plan (that is, an explanation of how MySQL would execute a query).

The following discussion uses the DESCRIBE and EXPLAIN keywords in accordance with those uses, but the MySQL parser treats them as completely synonymous.

Obtaining Table Structure Information

DESCRIBE provides information about the columns in a table:

mysql> DESCRIBE City;
+------------+----------+------+-----+---------+----------------+
| Field      | Type     | Null | Key | Default | Extra          |
+------------+----------+------+-----+---------+----------------+
| Id         | int(11)  | NO   | PRI | NULL    | auto_increment |
| Name       | char(35) | NO   |     |         |                |
| Country    | char(3)  | NO   | UNI |         |                |
| District   | char(20) | YES  | MUL |         |                |
| Population | int(11)  | NO   |     | 0       |                |
+------------+----------+------+-----+---------+----------------+

DESCRIBE is a shortcut for SHOW COLUMNS. These statements also display information for views. The description for SHOW COLUMNS provides more information about the output columns. See Section 15.7.7.6, “SHOW COLUMNS Statement”.

By default, DESCRIBE displays information about all columns in the table. col_name, if given, is the name of a column in the table. In this case, the statement displays information only for the named column. wild, if given, is a pattern string. It can contain the SQL % and _ wildcard characters. In this case, the statement displays output only for the columns with names matching the string. There is no need to enclose the string within quotation marks unless it contains spaces or other special characters.

The DESCRIBE statement is provided for compatibility with Oracle.

The SHOW CREATE TABLE, SHOW TABLE STATUS, and SHOW INDEX statements also provide information about tables. See Section 15.7.7, “SHOW Statements”.

The explain_format system variable has no effect on the output of EXPLAIN when used to obtain information about table columns.

Obtaining Execution Plan Information

The EXPLAIN statement provides information about how MySQL executes statements:

  • EXPLAIN works with SELECT, DELETE, INSERT, REPLACE, UPDATE, and TABLE statements.

  • When EXPLAIN is used with an explainable statement, MySQL displays information from the optimizer about the statement execution plan. That is, MySQL explains how it would process the statement, including information about how tables are joined and in which order. For information about using EXPLAIN to obtain execution plan information, see Section 10.8.2, “EXPLAIN Output Format”.

  • When EXPLAIN is used with FOR CONNECTION connection_id rather than an explainable statement, it displays the execution plan for the statement executing in the named connection. See Section 10.8.4, “Obtaining Execution Plan Information for a Named Connection”.

  • For explainable statements, EXPLAIN produces additional execution plan information that can be displayed using SHOW WARNINGS. See Section 10.8.3, “Extended EXPLAIN Output Format”.

  • EXPLAIN is useful for examining queries involving partitioned tables. See Section 26.3.5, “Obtaining Information About Partitions”.

  • The FORMAT option can be used to select the output format. TRADITIONAL presents the output in tabular format. This is the default if no FORMAT option is present. JSON format displays the information in JSON format. TREE provides tree-like output with more precise descriptions of query handling than the TRADITIONAL format; it is the only format which shows hash join usage (see Section 10.2.1.4, “Hash Join Optimization”) and is always used for EXPLAIN ANALYZE.

    In MySQL 9.0, the default output format used by EXPLAIN (that is, when it has no FORMAT option) is determined by the value of the explain_format system variable. The precise effects of this variable are described later in this section.

    MySQL 9.0 supports an additional INTO option with EXPLAIN FORMAT=JSON, which enables saving the JSON formatted output into a user variable, like this:

    mysql> EXPLAIN FORMAT=JSON INTO @myselect 
        ->     SELECT name FROM a WHERE id = 2;
    Query OK, 0 rows affected (0.00 sec)
    
    mysql> SELECT @myselect\G
    *************************** 1. row ***************************
    @myex: {
      "query_block": {
        "select_id": 1,
        "cost_info": {
          "query_cost": "1.00"
        },
        "table": {
          "table_name": "a",
          "access_type": "const",
          "possible_keys": [
            "PRIMARY"
          ],
          "key": "PRIMARY",
          "used_key_parts": [
            "id"
          ],
          "key_length": "4",
          "ref": [
            "const"
          ],
          "rows_examined_per_scan": 1,
          "rows_produced_per_join": 1,
          "filtered": "100.00",
          "cost_info": {
            "read_cost": "0.00",
            "eval_cost": "0.10",
            "prefix_cost": "0.00",
            "data_read_per_join": "408"
          },
          "used_columns": [
            "id",
            "name"
          ]
        }
      }
    }
    1 row in set (0.00 sec)

    This works with any explainable statement (SELECT, TABLE, INSERT, UPDATE, REPLACE, or DELETE). Examples using UPDATE and DELETE statements are shown here:

    mysql> EXPLAIN FORMAT=JSON INTO @myupdate 
        ->   UPDATE a SET name2 = "garcia" WHERE id = 3;              
    Query OK, 0 rows affected (0.00 sec)
    
    mysql> EXPLAIN FORMAT=JSON INTO @mydelete 
        ->     DELETE FROM a WHERE name1 LIKE '%e%';
    Query OK, 0 rows affected (0.00 sec)
    
    mysql> SELECT @myupdate, @mydelete\G
    *************************** 1. row ***************************
    @myupdate: {
      "query_block": {
        "select_id": 1,
        "table": {
          "update": true,
          "table_name": "a",
          "access_type": "range",
          "possible_keys": [
            "PRIMARY"
          ],
          "key": "PRIMARY",
          "used_key_parts": [
            "id"
          ],
          "key_length": "4",
          "ref": [
            "const"
          ],
          "rows_examined_per_scan": 1,
          "filtered": "100.00",
          "attached_condition": "(`db`.`a`.`id` = 3)"
        }
      }
    }
    @mydelete: {
      "query_block": {
        "select_id": 1,
        "table": {
          "delete": true,
          "table_name": "a",
          "access_type": "ALL",
          "rows_examined_per_scan": 2,
          "filtered": "100.00",
          "attached_condition": "(`db`.`a`.`name1` like '%e%')"
        }
      }
    }
    1 row in set (0.00 sec)

    You can work with this value using MySQL JSON functions as you would with any other JSON value, as in these examples using JSON_EXTRACT():

    mysql> SELECT JSON_EXTRACT(@myselect, "$.query_block.table.key");
    +----------------------------------------------------+
    | JSON_EXTRACT(@myselect, "$.query_block.table.key") |
    +----------------------------------------------------+
    | "PRIMARY"                                          |
    +----------------------------------------------------+
    1 row in set (0.01 sec)
    
    mysql> SELECT JSON_EXTRACT(@myupdate, "$.query_block.table.access_type") AS U_acc,
        ->        JSON_EXTRACT(@mydelete, "$.query_block.table.access_type") AS D_acc;
    +---------+-------+
    | U_acc   | D_acc |
    +---------+-------+
    | "range" | "ALL" |
    +---------+-------+
    1 row in set (0.00 sec)

    See also Section 14.17, “JSON Functions”.

    Trying to use an INTO clause without explicitly including FORMAT=JSON causes EXPLAIN to be rejected with ER_EXPLAIN_INTO_IMPLICIT_FORMAT_NOT_SUPPORTED. This is true regardless of the current value of the explain_format system variable.

    The INTO clause is not supported with FOR CONNECTION.

    INTO is also not supported with EXPLAIN ANALYZE when explain_json_format_version=1.

    Important

    If, for any reason, the statement to be analyzed is rejected, the user variable is not updated.

  • MySQL 9.0 supports a FOR SCHEMA clause, which causes EXPLAIN to behave as if the statement to be analyzed had been executed in the named database; FOR DATABASE is supported as a synonym. A simple example of use is shown here:

    mysql> USE b;
    Database changed
    mysql> CREATE SCHEMA s1;
    Query OK, 1 row affected (0.01 sec)
    
    mysql> CREATE SCHEMA s2;
    Query OK, 1 row affected (0.01 sec)
    
    mysql> USE s1;
    Database changed
    mysql> CREATE TABLE t (c1 INT NOT NULL AUTO_INCREMENT PRIMARY KEY, c2 INT NOT NULL);
    Query OK, 0 rows affected (0.04 sec)
    
    mysql> USE s2;
    Database changed
    mysql> CREATE TABLE t (c1 INT NOT NULL AUTO_INCREMENT PRIMARY KEY, c2 INT NOT NULL, KEY i1 (c2));
    Query OK, 0 rows affected (0.04 sec)
    
    mysql> USE b;
    Database changed
    mysql> EXPLAIN FORMAT=TREE FOR SCHEMA s1 SELECT * FROM t WHERE c2 > 50\G
    *************************** 1. row ***************************
    EXPLAIN: -> Filter: (t.c2 > 50)  (cost=0.35 rows=1)
        -> Table scan on t  (cost=0.35 rows=1)
    
    1 row in set (0.00 sec)
    
    mysql> EXPLAIN FORMAT=TREE FOR SCHEMA s2 SELECT * FROM t WHERE c2 > 50\G
    *************************** 1. row ***************************
    EXPLAIN: -> Filter: (t.c2 > 50)  (cost=0.35 rows=1)
        -> Covering index scan on t using i1  (cost=0.35 rows=1)
    
    1 row in set (0.00 sec)

    If the database does not exist, the statement is rejected with ER_BAD_DB_ERROR. If the user does not have the necessary privileges to run the statement, it is rejected with ER_DBACCESS_DENIED_ERROR.

    FOR SCHEMA is not compatible with FOR CONNECTION.

EXPLAIN requires the same privileges required to execute the explained statement. Additionally, EXPLAIN also requires the SHOW VIEW privilege for any explained view. EXPLAIN ... FOR CONNECTION also requires the PROCESS privilege if the specified connection belongs to a different user.

The explain_format system variable determines the format of the output from EXPLAIN when used to display a query execution plan. This variable can take any of the values used with the FORMAT option, with the addition of DEFAULT as a synonym for TRADITIONAL. The following example uses the country table from the world database which can be obtained from MySQL: Other Downloads:

mysql> USE world; # Make world the current database
Database changed

Checking the value of explain_format, we see that it has the default value, and that EXPLAIN (with no FORMAT option) therefore uses the traditional tabular output:

mysql> SELECT @@explain_format;
+------------------+
| @@explain_format |
+------------------+
| TRADITIONAL      |
+------------------+
1 row in set (0.00 sec)

mysql> EXPLAIN SELECT Name FROM country WHERE Code Like 'A%';
+----+-------------+---------+------------+-------+---------------+---------+---------+------+------+----------+-------------+
| id | select_type | table   | partitions | type  | possible_keys | key     | key_len | ref  | rows | filtered | Extra       |
+----+-------------+---------+------------+-------+---------------+---------+---------+------+------+----------+-------------+
|  1 | SIMPLE      | country | NULL       | range | PRIMARY       | PRIMARY | 12      | NULL |   17 |   100.00 | Using where |
+----+-------------+---------+------------+-------+---------------+---------+---------+------+------+----------+-------------+
1 row in set, 1 warning (0.00 sec)

If we set the value of explain_format to TREE, then rerun the same EXPLAIN statement, the output uses the tree-like format:

mysql> SET @@explain_format=TREE;
Query OK, 0 rows affected (0.00 sec)

mysql> SELECT @@explain_format;
+------------------+
| @@explain_format |
+------------------+
| TREE             |
+------------------+
1 row in set (0.00 sec)

mysql> EXPLAIN SELECT Name FROM country WHERE Code LIKE 'A%';
+--------------------------------------------------------------------------------------------------------------+
| EXPLAIN                                                                                                      |
+--------------------------------------------------------------------------------------------------------------+
| -> Filter: (country.`Code` like 'A%')  (cost=3.67 rows=17)
    -> Index range scan on country using PRIMARY over ('A' <= Code <= 'A????????')  (cost=3.67 rows=17)  |
+--------------------------------------------------------------------------------------------------------------+
1 row in set, 1 warning (0.00 sec)

As stated previously, the FORMAT option overrides this setting. Executing the same EXPLAIN statement using FORMAT=JSON instead of FORMAT=TREE shows that this is the case:

mysql> EXPLAIN FORMAT=JSON SELECT Name FROM country WHERE Code LIKE 'A%';
+------------------------------------------------------------------------------+
| EXPLAIN                                                                      |
+------------------------------------------------------------------------------+
| {
  "query_block": {
    "select_id": 1,
    "cost_info": {
      "query_cost": "3.67"
    },
    "table": {
      "table_name": "country",
      "access_type": "range",
      "possible_keys": [
        "PRIMARY"
      ],
      "key": "PRIMARY",
      "used_key_parts": [
        "Code"
      ],
      "key_length": "12",
      "rows_examined_per_scan": 17,
      "rows_produced_per_join": 17,
      "filtered": "100.00",
      "cost_info": {
        "read_cost": "1.97",
        "eval_cost": "1.70",
        "prefix_cost": "3.67",
        "data_read_per_join": "16K"
      },
      "used_columns": [
        "Code",
        "Name"
      ],
      "attached_condition": "(`world`.`country`.`Code` like 'A%')"
    }
  }
}                                                                              |
+------------------------------------------------------------------------------+
1 row in set, 1 warning (0.00 sec)

To return the default output of EXPLAIN to the tabular format, set explain_format to TRADITIONAL. Alternatively, you can set it to DEFAULT, which has the same effect, as shown here:

mysql> SET @@explain_format=DEFAULT;
Query OK, 0 rows affected (0.00 sec)

mysql> SELECT @@explain_format;
+------------------+
| @@explain_format |
+------------------+
| TRADITIONAL      |
+------------------+
1 row in set (0.00 sec)

MySQL 9.0 supports two versions of the JSON output format. Version 1 is the linear format always used in MySQL 8.2 and earlier; this remains the default in MySQL 9.0, and is used in the examples already shown in this section. Version 2 of the JSON output format is based on access paths, and is intended to provide compatibility with future versions of the MySQL Optimizer. You can switch to the Version 2 format by setting the value of the explain_json_format_version server system variable to 2, as shown here for the same EXPLAIN statement used in the previous example:

mysql> SELECT @@explain_json_format_version;
+-------------------------------+
| @@explain_json_format_version |
+-------------------------------+
|                             1 |
+-------------------------------+
1 row in set (0.00 sec)

mysql> SET @@explain_json_format_version = 2;
Query OK, 0 rows affected (0.00 sec)

mysql> SELECT @@explain_json_format_version;
+-------------------------------+
| @@explain_json_format_version |
+-------------------------------+
|                             2 |
+-------------------------------+
1 row in set (0.00 sec)

mysql> EXPLAIN FORMAT=JSON SELECT Name FROM country WHERE Code LIKE 'A%';
+------------------------------------------------------------------------------+
| EXPLAIN                                                                      |
+------------------------------------------------------------------------------+
| {
  "query": "/* select#1 */ select `world`.`country`.`Name` AS `Name` from `world`.`country` where (`world`.`country`.`Code` like 'A%')",
  "inputs": [
    {
      "ranges": [
        "('A' <= Code <= 'A????????')"
      ],
      "covering": false,
      "operation": "Index range scan on country using PRIMARY over ('A' <= Code < 'A????????')",
      "index_name": "PRIMARY",
      "table_name": "country",
      "access_type": "index",
      "estimated_rows": 17.0,
      "index_access_type": "index_range_scan",
      "estimated_total_cost": 3.668778400708174
    }
  ],
  "condition": "(country.`Code` like 'A%')",
  "operation": "Filter: (country.`Code` like 'A%')",
  "access_type": "filter",
  "estimated_rows": 17.0,
  "estimated_total_cost": 3.668778400708174
}                                                                              |
+------------------------------------------------------------------------------+

Setting explain_json_format_version = 2 also enables support for an INTO clause with EXPLAIN ANALYZE FORMAT=JSON, which enables you to store the JSON output in a user variable, as shown here:

mysql> EXPLAIN ANALYZE FORMAT=JSON INTO @v1
    ->   SELECT Name FROM country WHERE Code LIKE 'A%'\G
*************************** 1. row ***************************
@v1: {
  "query": "/* select#1 */ select `world`.`country`.`Name` AS `Name` from `world`.`country` where (`world`.`country`.`Code` like 'A%')",
  "inputs": [
    {
      "ranges": [
        "('A' <= Code <= 'A????????')"
      ],
      "covering": false,
      "operation": "Index range scan on country using PRIMARY over ('A' <= Code <= 'A????????')",
      "index_name": "PRIMARY",
      "table_name": "country",
      "access_type": "index",
      "actual_rows": 17.0,
      "key_columns": [
        "Code"
      ],
      "schema_name": "world",
      "actual_loops": 1,
      "used_columns": [
        "Code",
        "Name"
      ],
      "estimated_rows": 17.0,
      "index_access_type": "index_range_scan",
      "actual_last_row_ms": 0.097402,
      "actual_first_row_ms": 0.08752700000000001,
      "estimated_total_cost": 3.668778400708174
    }
  ],
  "condition": "(country.`Code` like 'A%')",
  "operation": "Filter: (country.`Code` like 'A%')",
  "query_type": "select",
  "access_type": "filter",
  "actual_rows": 17.0,
  "actual_loops": 1,
  "estimated_rows": 17.0,
  "filter_columns": [
    "world.country.`Code`"
  ],
  "actual_last_row_ms": 0.10903299999999999,
  "actual_first_row_ms": 0.09328499999999999,
  "estimated_total_cost": 3.668778400708174
}

You can use the variable as an argument to JSON functions to obtain specific items of information from the value, like this:

mysql> SELECT JSON_EXTRACT(@v1,'$.index_name') AS iname,
    ->        JSON_EXTRACT(@v1, '$.table_name') AS tname\G
*************************** 1. row ***************************
iname: "PRIMARY"
tname: "country"
1 row in set (0.00 sec)

This form of EXPLAIN ANALYZE requires an explicit FORMAT=JSON clause, and is supported only with SELECT statements. An optional FOR SCHEMA option is also supported, but not required. (FOR DATABASE can also be used, instead.) The INTO clause is supported with FORMAT=JSON only when explain_json_format_version is equal to 2; otherwise the statement fails with EXPLAIN ANALYZE does not support FORMAT=JSON with explain_json_format_version=1.

After using the Version 2 format, you can cause the JSON output from all subsequent EXPLAIN FORMAT=JSON statements to revert to the Version 1 format by setting explain_json_format_version back to 1 (the default).

The value of explain_json_format_version determines the version of the JSON output format employed by all EXPLAIN statements which use it, whether the JSON format is used because a given EXPLAIN statement includes an explicit FORMAT=JSON option, or because the JSON format is used automatically due to the explain_format system variable being set to JSON.

With the help of EXPLAIN, you can see where you should add indexes to tables so that the statement executes faster by using 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 a SELECT statement, begin the statement with SELECT STRAIGHT_JOIN rather than just SELECT. (See Section 15.2.13, “SELECT Statement”.)

The optimizer trace may sometimes provide information complementary to that of EXPLAIN. However, the optimizer trace format and content are subject to change between versions. For details, see MySQL Internals: Tracing the Optimizer.

If you have a problem with indexes not being used when you believe that they should be, run ANALYZE TABLE to update table statistics, such as cardinality of keys, that can affect the choices the optimizer makes. See Section 15.7.3.1, “ANALYZE TABLE Statement”.

Note

MySQL Workbench has a Visual Explain capability that provides a visual representation of EXPLAIN output. See Tutorial: Using Explain to Improve Query Performance.

Obtaining Information with EXPLAIN ANALYZE

EXPLAIN ANALYZE runs a statement and produces EXPLAIN output along with timing and additional, iterator-based, information about how the optimizer's expectations matched the actual execution. For each iterator, the following information is provided:

  • Estimated execution cost

    (Some iterators are not accounted for by the cost model, and so are not included in the estimate.)

  • Estimated number of returned rows

  • Time to return first row

  • Time spent executing this iterator (including child iterators, but not parent iterators), in milliseconds.

    (When there are multiple loops, this figure shows the average time per loop.)

  • Number of rows returned by the iterator

  • Number of loops

The query execution information is displayed using the TREE output format, in which nodes represent iterators. EXPLAIN ANALYZE uses an output format which can optionally be specified explicitly using FORMAT=TREE or FORMAT=JSON; the default is TREE. FORMAT=JSON can be used only if explain_json_format_version is set to 2.

EXPLAIN ANALYZE can be used with SELECT statements, multi-table UPDATE and DELETE statements, and TABLE statements.

You can terminate this statement using KILL QUERY or CTRL-C.

EXPLAIN ANALYZE cannot be used with FOR CONNECTION.

Example output:

mysql> SELECT @@explain_format;
+------------------+
| @@explain_format |
+------------------+
| TRADITIONAL      |
+------------------+

mysql> EXPLAIN ANALYZE SELECT * FROM t1 JOIN t2 ON (t1.c1 = t2.c2)\G
*************************** 1. row ***************************
EXPLAIN: -> Inner hash join (t2.c2 = t1.c1)  (cost=3.5 rows=5) 
(actual time=0.121..0.131 rows=1 loops=1) 
    -> Table scan on t2  (cost=0.07 rows=5) 
(actual time=0.0126..0.0221 rows=5 loops=1) 
    -> Hash
        -> Table scan on t1  (cost=0.75 rows=5) 
(actual time=0.0372..0.0534 rows=5 loops=1)

mysql> EXPLAIN ANALYZE FORMAT=TREE SELECT * FROM t3 WHERE i > 8\G
*************************** 1. row ***************************
EXPLAIN: -> Filter: (t3.i > 8)  (cost=0.75 rows=1.67) 
(actual time=0.0484..0.0542 rows=1 loops=1)
    -> Table scan on t3  (cost=0.75 rows=5) 
(actual time=0.0417..0.0494 rows=5 loops=1)

mysql> EXPLAIN ANALYZE FORMAT=JSON SELECT * FROM t3 WHERE pk < 17\G
*************************** 1. row ***************************
EXPLAIN: {
  "query": "/* select#1 */ select `a`.`t3`.`pk` AS `pk`,`a`.`t3`.`i` AS `i` from `a`.`t3` where (`a`.`t3`.`pk` < 17)",
  "inputs": [
    {
      "ranges": [
        "(pk < 17)"
      ],
      "covering": false,
      "operation": "Index range scan on t3 using PRIMARY over (pk < 17)",
      "index_name": "PRIMARY",
      "table_name": "t3",
      "access_type": "index",
      "actual_rows": 3.0,
      "key_columns": [
        "pk"
      ],
      "schema_name": "a",
      "actual_loops": 1,
      "used_columns": [
        "pk",
        "i"
      ],
      "estimated_rows": 3.0,
      "index_access_type": "index_range_scan",
      "actual_last_row_ms": 0.034214,
      "actual_first_row_ms": 0.03052,
      "estimated_total_cost": 0.860618301731245
    }
  ],
  "condition": "(t3.pk < 17)",
  "operation": "Filter: (t3.pk < 17)",
  "query_type": "select",
  "access_type": "filter",
  "actual_rows": 3.0,
  "actual_loops": 1,
  "estimated_rows": 3.0,
  "filter_columns": [
    "a.t3.pk"
  ],
  "actual_last_row_ms": 0.038189,
  "actual_first_row_ms": 0.033429,
  "estimated_total_cost": 0.860618301731245
}

The tables used in the example output were created by the statements shown here:

CREATE TABLE t1 (
    c1 INTEGER DEFAULT NULL,
    c2 INTEGER DEFAULT NULL
);

CREATE TABLE t2 (
    c1 INTEGER DEFAULT NULL,
    c2 INTEGER DEFAULT NULL
);

CREATE TABLE t3 (
    pk INTEGER NOT NULL PRIMARY KEY,
    i INTEGER DEFAULT NULL
);

Values shown for actual time in the output of this statement are expressed in milliseconds.

explain_format has the following effects on EXPLAIN ANALYZE:

  • If the value of this variable is TRADITIONAL or TREE (or the synonym DEFAULT), EXPLAIN ANALYZE uses the TREE format unless the statement includes FORMAT=JSON.

  • If the value of explain_format is JSON, EXPLAIN ANALYZE uses the JSON format unless FORMAT=TREE is specified as part of the statement.

Using FORMAT=TRADITIONAL or FORMAT=DEFAULT with EXPLAIN ANALYZE always raises an error, regardless of the value of explain_format.

In MySQL 9.0, numbers in the output of EXPLAIN ANALYZE and EXPLAIN FORMAT=TREE are formatted according to the following rules:

  • Numbers in the range 0.001-999999.5 are printed as decimal numbers.

    Decimal numbers less than 1000 have three significant digits; the remainder have four, five, or six.

  • Numbers outside the range 0.001-999999.5 are printed in engineering format. Examples of such values are 1.23e+9 and 934e-6.

  • No trailing zeros are printed. For example, we print 2.3 rather than 2.30, and 1.2e+6 rather than 1.20e+6.

  • Numbers less than 1e-12 are printed as 0.