Updated on 2025-10-23 GMT+08:00

EXPLAIN

Description

Shows the execution plan of an SQL statement.

The execution plan shows how the tables referenced by the SQL statement will be scanned, for example, by plain sequential scan or index scan. If multiple tables are referenced, the execution plan also shows 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 plan generator's guess at how long it will take to run the statement.

The ANALYZE option causes the statement to be actually executed. 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 estimated value is close to the actual one.

Precautions

  • The statement is actually executed when the ANALYZE option is used. If you want to use EXPLAIN on an INSERT, UPDATE, DELETE, or EXECUTE statement without letting the statement affect your data, use this approach:
    START TRANSACTION;
    EXPLAIN ANALYZE ...;
    ROLLBACK;
  • After parameterized Remotequery is generated in a statement and max_datanode_for_plan is set to a value greater than 0, the execution plan of parameterized Remotequery on DNs cannot be viewed. To view the execution plan of parameterized Remotequery on DNs, perform the following steps:
    -- 1. Use the auto_explain parameter to view a DN plan.
    SET enable_auto_explain = on;
    SET auto_explain_level = log;
    SET enable_opfusion=off;
    -- If you do not want to modify the data, do as follows:
    START TRANSACTION;
    EXPLAIN ANALYZE ...;
    ROLLBACK;
    -- Otherwise, do as follows:
    EXPLAIN ANALYZE ...;
    -- Then, the execution plan on each DN is recorded in gs_log of the DN.
    
    -- 2. Use the statement_history view to view the DN plan.
    -- Use the dynamic_func_control function to track.
    SELECT * FROM dynamic_func_control('GLOBAL', 'STMT', 'TRACK', '{"unique_sql_id", "L2"}');
    -- Run the SQL statement to be viewed.
    SELECT ...;
    -- View the statement plan on the corresponding DN.
    SELECT unique_query_id,query_plan from statement_history WHERE unique_query_id='unique_sql_id';

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 ] |
        VERBOSE [ boolean ] |
        COSTS [ boolean ] |
        CPU [ boolean ] |
        DETAIL [ boolean ] |
        NODES [ boolean ] |
        NUM_NODES [ boolean ] |
        BUFFERS [ boolean ] |
        TIMING [ boolean ] |
        PLAN [ boolean ] |
        BLOCKNAME [ boolean ] |  
        PERFORMANCE | 
        FORMAT { TEXT | XML | JSON | YAML }
  • Display the execution plan of an SQL statement, where options are in order.
    EXPLAIN  { [   ANALYZE    ] [ VERBOSE  ] } statement;

Parameters

  • statement

    Specifies the SQL statement to explain.

  • ANALYZE 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.

    The options are as follows:

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

    Specifies whether to display additional information regarding the plan.

    The options are as follows:

    • 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.

    The options are as follows:

    • 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.

    The options are as follows:

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

    Specifies whether to display information about database nodes. This parameter must be used together with ANALYZE.

    The options are as follows:

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

    Specifies whether to display information about the nodes executed by query.

    The options are as follows:

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

    Specifies whether to display the number of executing nodes.

    The options are as follows:

    • 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.

    The options are as follows:

    • 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.

    The options are as follows:

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

    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 is not displayed on the screen. Therefore, this parameter cannot be used together with other parameters when it is set to on.

    The options are as follows:

    • ON (default): stores the execution plan in PLAN_TABLE and does not display it on the screen. If the plan is stored successfully, "EXPLAIN SUCCESS" is returned.
    • OFF: does not store the execution plan but displays it 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, each 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.

    • TRUE (default value): The name of the query block where each operation is located is displayed in the Query Block column. This option must be used in the pretty mode.
    • FALSE: The plan display is not affected.
  • 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.
    • Network Poll Time: indicates the duration for the libcomm receiver to wait for data during distributed stream network communication.
    • Stream Send time: indicates the time consumed by libcomm or libpq to send data during distributed stream network communication.
    • OS Kernel Send time: indicates the time required for the OS layer to send data during distributed stream network communication. This parameter is displayed only when the value is greater than 0.
    • Wait Quota time: indicates the duration for libcomm to wait for the peer end to send the quota traffic control size during distributed stream network communication. This parameter is displayed only when the value is greater than 0.
    • Data Serialize time: indicates the data serialization time during distributed stream network communication.
    • Data Copy time: indicates the data replication time during distributed stream network communication. This parameter is displayed only when the value is greater than 0.

Examples

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

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

-- Create the tpcds.customer_address_p1 table.
m_db=# CREATE TABLE tpcds.customer_address_p1 LIKE tpcds.customer_address;

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

-- Display an execution plan for simple queries in the table.
m_db=# EXPLAIN SELECT * FROM tpcds.customer_address_p1;
                    QUERY PLAN
--------------------------------------------------
 Data Node Scan  (cost=0.00..0.00 rows=0 width=0)
   Node/s: All datanodes
(2 rows)

-- Generate an execution plan in JSON format (with explain_perf_mode being normal).
m_db=# EXPLAIN(FORMAT JSON) SELECT * FROM tpcds.customer_address_p1;
              QUERY PLAN
--------------------------------------
 [                                   +
   {                                 +
     "Plan": {                       +
       "Node Type": "Data Node Scan",+
       "Startup Cost": 0.00,         +
       "Total Cost": 0.00,           +
       "Plan Rows": 0,               +
       "Plan Width": 0,              +
       "Nodes": "All datanodes"      +
     }                               +
   }                                 +
 ]
(1 row)

-- If there is an index and we use a query with an indexable WHERE condition, a different plan may be displayed.
m_db=# EXPLAIN SELECT * FROM tpcds.customer_address_p1 WHERE ca_address_sk=10000;
                    QUERY PLAN
--------------------------------------------------
 Data Node Scan  (cost=0.00..0.00 rows=0 width=0)
   Node/s: datanode2
(2 rows)

-- Generate an execution plan in YAML format (with explain_perf_mode being normal).
m_db=# EXPLAIN(FORMAT YAML) SELECT * FROM tpcds.customer_address_p1 WHERE ca_address_sk=10000;
           QUERY PLAN
---------------------------------
 - Plan:                        +
     Node Type: "Data Node Scan"+
     Startup Cost: 0.00         +
     Total Cost: 0.00           +
     Plan Rows: 0               +
     Plan Width: 0              +
     Nodes: "datanode2"
(1 row)

-- Suppress the execution plan of cost estimation.
m_db=# EXPLAIN(COSTS FALSE) SELECT * FROM tpcds.customer_address_p1 WHERE ca_address_sk=10000;
     QUERY PLAN
---------------------
 Data Node Scan
   Node/s: datanode2
(2 rows)

-- Generate an execution plan with aggregate functions for a query.
m_db=# EXPLAIN SELECT SUM(ca_address_sk) FROM tpcds.customer_address_p1 WHERE ca_address_sk<10000;
                                      QUERY PLAN
--------------------------------------------------------------------------------------
 Aggregate  (cost=13.24..13.28 rows=1 width=12)
   ->  Streaming (type: GATHER)  (cost=13.24..13.28 rows=2 width=12)
         Node/s: All datanodes
         ->  Aggregate  (cost=13.17..13.18 rows=2 width=12)
               ->  Seq Scan on customer_address_p1  (cost=0.00..13.16 rows=7 width=4)
                     Filter: (ca_address_sk < 10000)
(6 rows)

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

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

-- Delete the schema.
m_db=# DROP SCHEMA tpcds;

Helpful Links

ANALYZE