EXPLAIN
Description
Displays 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. - 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 seeing whether the planner's estimates are close to reality.
Precautions
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 ] | 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.
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.
Value range:
- TRUE (default): displays it.
- FALSE: does not display it.
- DETAIL boolean
Displays information about database nodes.
Value range:
- TRUE (default): displays it.
- FALSE: does not display it.
- BUFFERS boolean
Specifies whether to display buffer usage.
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.
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 in PLAN_TABLE 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.
- TRUE (default value): When the plan is displayed, 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. See Hint Specifying the Query Block Where the Hint Is Located.
- 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.
- OPTEVAL boolean
Indicates 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 -------------------------------------------------- Data Node Scan (cost=0.00..0.00 rows=0 width=0) Node/s: All dbnodes (2 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": "Data Node Scan",+ "Startup Cost": 0.00, + "Total Cost": 0.00, + "Plan Rows": 0, + "Plan Width": 0, + "Node/s": "All dbnodes" + } + } + ] (1 row) -- If there is an index and we use a query with an indexable WHERE condition, EXPLAIN might show a different plan. gaussdb=# 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: dn_6005_6006 (2 rows) -- 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: "Data Node Scan"+ Startup Cost: 0.00 + Total Cost: 0.00 + Plan Rows: 0 + Plan Width: 0 + Node/s: "dn_6005_6006" (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 ------------------------ Data Node Scan Node/s: dn_6005_6006 (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=18.19..14.32 rows=1 width=4) -> Streaming (type: GATHER) (cost=18.19..14.32 rows=3 width=4) Node/s: All dbnodes -> Aggregate (cost=14.19..14.20 rows=3 width=4) -> Seq Scan on customer_address_p1 (cost=0.00..14.18 rows=10 width=4) Filter: (ca_address_sk < 10000) (6 rows) -- Create a level-2 partitioned table. gaussdb=# CREATE TABLE range_list gaussdb-# ( gaussdb(# month_code VARCHAR2 ( 30 ) NOT NULL , gaussdb(# dept_code VARCHAR2 ( 30 ) NOT NULL , gaussdb(# user_no VARCHAR2 ( 30 ) NOT NULL , gaussdb(# sales_amt int gaussdb(# ) gaussdb-# PARTITION BY RANGE (month_code) SUBPARTITION BY LIST (dept_code) gaussdb-# ( gaussdb(# PARTITION p_201901 VALUES LESS THAN( '201903' ) gaussdb(# ( gaussdb(# SUBPARTITION p_201901_a values ('1'), gaussdb(# SUBPARTITION p_201901_b values ('2') gaussdb(# ), gaussdb(# PARTITION p_201902 VALUES LESS THAN( '201910' ) gaussdb(# ( gaussdb(# SUBPARTITION p_201902_a values ('1'), gaussdb(# SUBPARTITION p_201902_b values ('2') gaussdb(# ) gaussdb(# ); CREATE TABLE -- Run a query statement containing a level-2 partitioned table. -- Iterations and Sub Iterations specifies 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..13.81 rows=2 width=238) Iterations: 2, Sub Iterations: 2 -> Partitioned Seq Scan on range_list (cost=0.00..13.81 rows=2 width=238) 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 a schema. gaussdb=# DROP SCHEMA tpcds CASCADE;
Example 2
gaussdb=# explain (opteval on )select * from tb_a a, tb_b b where a.c1=b.c1 and a.c1=1;
id | operation | E-rows | E-width | E-costs
----+--------------------------------------------------+--------+---------+----------------
1 | -> Nested Loop (2,3) | 2401 | 30 | 0.000..312.321
2 | -> Index Scan using tb_a_idx_c1 on tb_a a | 49 | 15 | 0.000..141.090
3 | -> Materialize | 49 | 15 | 0.000..141.342
4 | -> Index Scan using tb_b_idx_c1 on tb_b b | 49 | 15 | 0.000..141.097
(4 rows)
Predicate Information (identified by plan id)
-----------------------------------------------
2 --Index Scan using tb_a_idx_c1 on tb_a a
Index Cond: (c1 = 1)
4 --Index Scan using tb_b_idx_c1 on tb_b b
Index Cond: (c1 = 1)
(4 rows)
Cost Evaluation Info (identified by plan id)
-----------------------------------------------------------------------------------------------------------------------------------------------------------
2 --Index Scan using tb_a_idx_c1 on tb_a a(id=#2#, rpages=1.00, ipages=1.00, selec=0.00488000, ml=0, iscost=1, lossy=0, uidx=0)
-> Seq Scan on tb_a a(id=#1#)
Filter: (c1 = 1)
Cost Info: (cost=0.00..180.00 tuples=10000.00, rpages=55.00, ipages=-1.00, selec=-1.00000000, ml=0, iscost=0, lossy=0, uidx=0)
-> Bitmap Heap Scan on tb_a a(id=#3#)
Recheck Cond: (c1 = 1)
Cost Info: (cost=10000000004.63..1000000006104.52 tuples=49.00, rpages=34.00, ipages=0.00, selec=0.00488000, ml=0, iscost=0, lossy=0, uidx=0)
-> Bitmap Index Scan using tb_a_idx_c1(id=#2#)
Index Cond: (c1 = 1)
Cost Info: (cost=0.00..4.62 tuples=49.00, rpages=1.00, ipages=1.00, selec=0.00488000, ml=0, iscost=1, lossy=0, uidx=0)
4 --Index Scan using tb_b_idx_c1 on tb_b b(id=#5#, rpages=1.00, ipages=1.00, selec=0.00491949, ml=1, iscost=1, lossy=0, uidx=0)
-> Seq Scan on tb_b b(id=#4#)
Filter: (c1 = 1)
Cost Info: (cost=0.00..180.00 tuples=10000.00, rpages=55.00, ipages=-1.00, selec=-1.00000000, ml=0, iscost=0, lossy=0, uidx=0)
-> Bitmap Heap Scan on tb_b b(id=#6#)
Recheck Cond: (c1 = 1)
Cost Info: (cost=10000000004.63..1000000006104.52 tuples=49.00, rpages=34.00, ipages=0.00, selec=0.00491949, ml=0, iscost=0, lossy=0, uidx=0)
-> Bitmap Index Scan using tb_b_idx_c1(id=#5#)
Index Cond: (c1 = 1)
Cost Info: (cost=0.00..4.62 tuples=49.00, rpages=1.00, ipages=1.00, selec=0.00491949, ml=1, iscost=1, lossy=0, uidx=0)
(20 rows)
For the Cost Evaluation Info (identified by plan id) plan block:
- 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.
- The preceding key parameters are described as follows:
- 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.
- rpage indicates the number of pages in the base table used during the cost model calculation.
- ipage indicates the number of pages in the index used during the cost model calculation.
- tuples indicates the number of tuples used in the cost model calculation.
- selec indicates the index selection rate used during cost model calculation. The value -1 indicates that the index selection rate of the current operator is invalid.
- 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.
- iscost indicates whether an event of ignoring the startup cost has occurred during model cost calculation.
- lossy indicates whether to trigger the lossy mechanism of bitmap heap scan during cost model calculation.
- uidx indicates whether to trigger the unique index first rule during cost model calculation.
Helpful Links
Feedback
Was this page helpful?
Provide feedbackThank you very much for your feedback. We will continue working to improve the documentation.See the reply and handling status in My Cloud VOC.
For any further questions, feel free to contact us through the chatbot.
Chatbot