Updated on 2024-06-03 GMT+08:00

EXPLAIN

Description

Shows the execution plan of an SQL statement.

The execution plan shows how the tables referenced by the statement will be scanned - by plain sequential scan, index scan, etc. - and if multiple tables are referenced, what join algorithms will be used to bring together the required rows from each input table.

The most critical part of the display is the estimated statement execution cost, which is the planner's guess at how long it will take to run the statement.

The ANALYZE option causes the statement to be actually executed, not only planned. The total elapsed time expended within each plan node (in milliseconds) and total number of rows it actually returned are added to the display. This is useful for determining whether the plan generator's estimate is close to the actual value.

Precautions

The statement is actually executed when ANALYZE is used. If you want to use EXPLAIN ANALYZE on an INSERT, UPDATE, DELETE, CREATE TABLE AS, or EXECUTE statement without letting the statement affect your data, use the following approach:
START TRANSACTION;
EXPLAIN ANALYZE ...;
ROLLBACK;

Syntax

  • Display the execution plan of an SQL statement, which supports multiple options and has no requirements for the order of options.
    EXPLAIN [ (  option  [, ...] )  ] statement;

    The syntax of the option clause is as follows:

    ANALYZE [ boolean ] |
        ANALYSE [ boolean ] |
        VERBOSE [ boolean ] |
        COSTS [ boolean ] |
        CPU [ boolean ] |
        DETAIL [ boolean ] |
        BUFFERS [ boolean ] |
        TIMING [ boolean ] |
        PLAN [ boolean ] |
        BLOCKNAME [ boolean ] |
        OUTLINE [ boolean ] |
        ADAPTCOST [ boolean ] |
        FORMAT { TEXT | XML | JSON | YAML }
        OPTEVAL [ boolean ]
  • Display the execution plan of an SQL statement, where options are in order.
    EXPLAIN  { [   ANALYZE  | ANALYSE    ] [ VERBOSE  ]  | PERFORMANCE  } statement;

Parameters

  • statement

    Specifies the SQL statement to explain.

  • ANALYZE boolean | ANALYSE boolean

    Specifies whether to display actual run times and other statistics. When two parameters are used at the same time, the latter one in option takes effect.

    Value range:

    • TRUE (default): displays them.
    • FALSE: does not display them.
  • VERBOSE boolean

    Specifies whether to display additional information regarding the plan.

    Value range:

    • TRUE (default): displays it.
    • FALSE: does not display it.
  • COSTS boolean

    Specifies whether to display the estimated total cost of each plan node, estimated number of rows, estimated width of each row.

    Value range:

    • TRUE (default): displays them.
    • FALSE: does not display them.
  • CPU boolean

    Specifies whether to display CPU usage. This parameter must be used together with ANALYZE or ANALYSE.

    Value range:

    • TRUE (default): displays it.
    • FALSE: does not display it.
  • DETAIL boolean

    Displays information about database nodes. This parameter must be used together with ANALYZE or ANALYSE.

    Value range:

    • TRUE (default): displays it.
    • FALSE: does not display it.
  • BUFFERS boolean

    Specifies whether to display buffer usage. This parameter must be used together with ANALYZE or ANALYSE.

    Value range:

    • TRUE: displays it.
    • FALSE (default): does not display it.
  • TIMING boolean

    Specifies whether to display the actual startup time and time spent on the output node. This parameter must be used together with ANALYZE or ANALYSE.

    Value range:

    • TRUE (default): displays them.
    • FALSE: does not display them.
  • PLAN boolean

    Specifies whether to store the execution plan in PLAN_TABLE. If this parameter is set to on, the execution plan is stored in PLAN_TABLE and not displayed on the screen. Therefore, this parameter cannot be used together with other parameters when it is set to on.

    Value range:

    • ON (default): The execution plan is stored in PLAN_TABLE and not printed on the screen. If the plan is stored successfully, "EXPLAIN SUCCESS" is returned.
    • OFF: The execution plan is not stored but is printed on the screen.
  • BLOCKNAME boolean

    Specifies whether to display the query block where each operation of the plan is located. When this option is enabled, the name of the query block where each operation is performed is displayed in the Query Block column. This helps users obtain the query block name and use hints to modify the execution plan.

  • OUTLINE boolean

    Determines whether to display outline hints of a plan.

    • ON: When a plan is displayed, outline hints are displayed below the plan. This option must be used in the pretty mode. See Outline Hint.
    • OFF (default value): The outline hints of the plan are not displayed.
  • ADAPTCOST boolean

    Specifies whether to display the cardinality estimation method of a plan in the normal mode.

    • ON (default): Display the cardinality estimation method, including the default method and feedback method, on the plan node in the normal mode. This parameter does not take effect for prepared statements.
    • OFF: Do not display the cardinality estimation method.
  • FORMAT

    Specifies the output format.

    Value range: TEXT, XML, JSON, and YAML

    Default value: TEXT

  • PERFORMANCE

    Prints all relevant information in execution. Some information is described as follows:

    • ex c/r: indicates the average number of CPU cycles used by each row, which is equal to (ex cyc) / (ex row).
    • ex row: indicates the number of executed rows.
    • ex cyc: indicates the number of used CPU cycles.
    • inc cyc: indicates the total number of CPU cycles used by subnodes.
    • shared hit: indicates the shared buffer hits of the operator.
    • loops: indicates the number of operator loop execution times.
    • total_calls: indicates the total number of generated elements.
    • remote query poll time stream gather: indicates the operator used to listen to the network poll time when data on each DN reaches the CN.
    • deserialize time: indicates the time required for deserialization.
    • estimated time: indicates the estimated time.
  • OPTEVAL boolean

    Specifies whether to display the cost elimination details of the scan operator (currently, only seqscan, indexscan, indexonlyscan and bitmapheapscan are supported). When this function is enabled, a plan block named Cost Evaluation Info (identified by plan id) is displayed in the execution plan. This option can only coexist with COSTS, VERBOSE, and FORMAT. For details about the parameters in the plan block, see Example 2.

    Value range:
    • TRUE: displays the cost elimination details of the SCAN operator.
    • FALSE (default): does not display it.

Example 1

-- Create a schema.
gaussdb=# CREATE SCHEMA tpcds; 

-- Create the tpcds.customer_address table.
gaussdb=# CREATE TABLE tpcds.customer_address
(
ca_address_sk         INTEGER           NOT NULL,
ca_address_id         CHARACTER(16)     NOT NULL
);
 
-- Insert multiple records into the table.
gaussdb=# INSERT INTO tpcds.customer_address VALUES (5000, 'AAAAAAAABAAAAAAA'),(10000, 'AAAAAAAACAAAAAAA');

-- Create the tpcds.customer_address_p1 table.
gaussdb=# CREATE TABLE tpcds.customer_address_p1 AS TABLE tpcds.customer_address;

-- Change the value of explain_perf_mode to normal.
gaussdb=# SET explain_perf_mode=normal;

-- Display an execution plan for simple queries in the table.
gaussdb=# EXPLAIN SELECT * FROM tpcds.customer_address_p1;
                               QUERY PLAN                               
------------------------------------------------------------------------
 Seq Scan on customer_address_p1  (cost=0.00..25.13 rows=1513 width=24)
(1 row)

-- Use the ANALYZE option to add runtime statistics to the output.
gaussdb=# EXPLAIN ANALYZE SELECT * FROM tpcds.customer_address_p1;
                                                    QUERY PLAN                                                    
--------------------------------------------------------------------------------------------- Seq Scan on customer_address_p1  (cost=0.00..25.13 rows=1513 width=24) (actual time=0.015..0.016 rows=2 loops=1)
 Total runtime: 0.108 ms
(2 rows)

-- Use the ANALYZE and CPU options to output the CPU usage information.
gaussdb=# EXPLAIN (ANALYZE,CPU)SELECT * FROM tpcds.customer_address_p1;
                                                    QUERY PLAN                                                    
--------------------------------------------------------------------------------------------- Seq Scan on customer_address_p1  (cost=0.00..25.13 rows=1513 width=24) (actual time=0.011..0.012 rows=2 loops=1)
   (CPU: ex c/r=47397856228403856, ex row=2, ex cyc=94795712456807712, inc cyc=94795712456807712)
 Total runtime: 0.092 ms
(3 rows)

-- Generate an execution plan in JSON format (with explain_perf_mode being normal).
gaussdb=# EXPLAIN(FORMAT JSON) SELECT * FROM tpcds.customer_address_p1;
                  QUERY PLAN                   
-----------------------------------------------
 [                                            +
   {                                          +
     "Plan": {                                +
       "Node Type": "Seq Scan",               +
       "Relation Name": "customer_address_p1",+
       "Alias": "customer_address_p1",        +
       "Startup Cost": 0.00,                  +
       "Total Cost": 25.13,                   +
       "Plan Rows": 1513,                     +
       "Plan Width": 24                       +
     }                                        +
   }                                          +
 ]
(1 row)

-- Generate an execution plan in YAML format (with explain_perf_mode being normal).
gaussdb=# EXPLAIN(FORMAT YAML) SELECT * FROM tpcds.customer_address_p1 WHERE ca_address_sk=10000;
                QUERY PLAN                
------------------------------------------
 - Plan:                                 +
     Node Type: "Seq Scan"               +
     Relation Name: "customer_address_p1"+
     Alias: "customer_address_p1"        +
     Startup Cost: 0.00                  +
     Total Cost: 28.91                   +
     Plan Rows: 8                        +
     Plan Width: 24                      +
     Filter: "(ca_address_sk = 10000)"
(1 row)

-- Suppress the execution plan of cost estimation.
gaussdb=# EXPLAIN(COSTS FALSE) SELECT * FROM tpcds.customer_address_p1 WHERE ca_address_sk=10000;
            QUERY PLAN             
-----------------------------------
 Seq Scan on customer_address_p1
   Filter: (ca_address_sk = 10000)
(2 rows)


-- Generate an execution plan with aggregate functions for a query.
gaussdb=# EXPLAIN SELECT SUM(ca_address_sk) FROM tpcds.customer_address_p1 WHERE ca_address_sk<10000;
                                 QUERY PLAN                                 
----------------------------------------------------------------------------
 Aggregate  (cost=30.17..30.18 rows=1 width=12)
   ->  Seq Scan on customer_address_p1  (cost=0.00..28.91 rows=504 width=4)
         Filter: (ca_address_sk < 10000)
(3 rows)

-- Create a level-2 partitioned table.
gaussdb=# CREATE TABLE range_list
(
    month_code VARCHAR2 ( 30 ) NOT NULL ,
    dept_code  VARCHAR2 ( 30 ) NOT NULL ,
    user_no    VARCHAR2 ( 30 ) NOT NULL ,
    sales_amt  int
)
PARTITION BY RANGE (month_code) SUBPARTITION BY LIST (dept_code)
(
  PARTITION p_201901 VALUES LESS THAN( '201903' )
  (
    SUBPARTITION p_201901_a values ('1'),
    SUBPARTITION p_201901_b values ('2')
  ),
  PARTITION p_201902 VALUES LESS THAN( '201910' )
  (
    SUBPARTITION p_201902_a values ('1'),
    SUBPARTITION p_201902_b values ('2')
  )
);

-- Run a query statement containing a level-2 partitioned table.
-- Iterations and Sub Iterations specify the numbers of level-1 and level-2 partitions that are traversed, respectively.
-- Selected Partitions specifies which level-1 partitions are actually scanned. Selected Subpartitions (p:s) indicates that s level-2 partitions under the pth level-1 partition are actually scanned. If all level-2 partitions under the level-1 partition are scanned, the value of s is ALL.
gaussdb=# EXPLAIN SELECT * FROM range_list WHERE dept_code = '1';
                                  QUERY PLAN                                   
-------------------------------------------------------------------------------
 Partition Iterator  (cost=0.00..17.68 rows=3 width=103)
   Iterations: 2, Sub Iterations: 2
   ->  Partitioned Seq Scan on range_list  (cost=0.00..17.68 rows=3 width=103)
         Filter: ((dept_code)::text = '1'::text)
         Selected Partitions:  1..2
         Selected Subpartitions:  1:1  2:1
(6 rows)

-- Delete the tpcds.customer_address_p1 table.
gaussdb=# DROP TABLE tpcds.customer_address_p1;

-- Delete the tpcds.customer_address table.
gaussdb=# DROP TABLE tpcds.customer_address;

-- Delete the range_list table.
gaussdb=# DROP TABLE range_list;

-- Delete a schema.
gaussdb=# DROP SCHEMA tpcds CASCADE;

Example 2

-- Create tb_a and tb_b.
gaussdb=# CREATE TABLE tb_a(c1 int);
gaussdb=# INSERT INTO tb_a VALUES(1),(2),(3);
gaussdb=# CREATE TABLE tb_b AS SELECT * FROM tb_a;

-- Display the cost elimination details of the SCAN operator.
gaussdb=# EXPLAIN (OPTEVAL on )SELECT * FROM tb_a a, tb_b b WHERE a.c1=b.c1 AND a.c1=1;
                             QUERY PLAN                             
--------------------------------------------------------------------
 Nested Loop  (cost=0.00..81.88 rows=144 width=8)
   ->  Seq Scan on tb_a a  (cost=0.00..40.03 rows=12 width=4)
         Filter: (c1 = 1)
   ->  Materialize  (cost=0.00..40.09 rows=12 width=4)
         ->  Seq Scan on tb_b b  (cost=0.00..40.03 rows=12 width=4)
               Filter: (c1 = 1)
(6 rows)

-- Delete the tb_a and tb_b tables.
gaussdb=# DROP TABLE tb_a;
gaussdb=# DROP TABLE tb_b;

For the Cost Evaluation Info (identified by plan id) plan block:

  1. The rows 2 -- and 4 -- represent the current winning operator, and the indentation plan blocks under each row represent the operators directly eliminated by the current winning operator. For example, operator 2 eliminates the Seq Scan and Bitmap Heap Scan operators.
  2. The preceding key parameters are described as follows:
    1. id indicates that the current operator is converted from a path with a specified ID. The value is used to locate a path in debug2 logs.
    2. rpage indicates the number of pages in the base table used during the cost model calculation.
    3. ipage indicates the number of pages in the index used during the cost model calculation.
    4. tuples indicates the number of tuples used in the cost model calculation.
    5. selec indicates the index selectivity used during cost model calculation. The value –1 indicates that the index selectivity of the current operator is invalid.
    6. ml indicates the ML model event that is currently triggered during cost model calculation. The value 1 indicates that the cache specified by effective_cache_size is sufficient, the value 2 indicates that the cache specified by effective_cache_size is insufficient, and the value 3 indicates that the cache specified by effective_cache_size is severely insufficient.
    7. iscost specifies whether an event of ignoring the startup cost has occurred during model cost calculation.
    8. lossy specifies whether to trigger the lossy mechanism of bitmap heap scan during cost model calculation.
    9. uidx specifies whether to trigger the unique index first rule during cost model calculation.

Helpful Links

ANALYZE | ANALYSE