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, 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
The statement is actually executed when the ANALYZE option 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 this approach:
1 2 3 |
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.
1
EXPLAIN [ ( option [, ...] ) ] statement;
The syntax of the option clause is as follows:
1 2 3 4 5 6 7 8 9 10 11 12
ANALYZE [ boolean ] | ANALYSE [ boolean ] | VERBOSE [ boolean ] | COSTS [ boolean ] | CPU [ boolean ] | DETAIL [ boolean ] | NODES [ boolean ] | NUM_NODES [ boolean ] | BUFFERS [ boolean ] | TIMING [ boolean ] | PLAN [ boolean ] | FORMAT { TEXT | XML | JSON | YAML }
- Display the execution plan of an SQL statement, where options are in order.
1
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.
Value range:
- TRUE (default): displays it.
- FALSE: does not display them.
- DETAIL boolean
Specifies whether to display DN information.
Value range:
- TRUE (default): displays it.
- FALSE: does not display it.
- NODES boolean
Specifies whether to display information about the nodes executed by query.
Value range:
- TRUE (default): displays it.
- FALSE: does not display it.
- NUM_NODES boolean
Specifies whether to display the number of executing 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:
- TRUE (default): The execution plan is stored in PLAN_TABLE and not displayed on the screen. If the plan is stored successfully, "EXPLAIN SUCCESS" is returned.
- FALSE: The execution plan is not stored but is printed on the screen.
- FORMAT
Specifies the output format.
Value range: TEXT, XML, JSON, and YAML
Default value: TEXT
- PERFORMANCE
Prints all relevant information in execution.
Examples
1 2 3 4 5 6 7 8 9 10 11 12 13 14 15 16 17 18 19 20 21 22 23 24 25 26 27 28 29 30 31 32 33 34 35 36 37 38 39 40 41 42 43 44 45 46 47 48 49 50 51 52 53 54 55 56 57 58 59 60 61 62 63 64 65 66 67 68 69 70 71 72 73 74 75 76 77 78 79 80 81 82 83 84 85 86 87 88 89 90 91 92 93 94 |
-- Create a schema. openGauss=# CREATE SCHEMA tpcds; -- Create the tpcds.customer_address table. openGauss=# CREATE TABLE tpcds.customer_address ( ca_address_sk INTEGER NOT NULL, ca_address_id CHARACTER(16) NOT NULL ); -- Insert multiple records into the table. openGauss=# INSERT INTO tpcds.customer_address VALUES (5000, 'AAAAAAAABAAAAAAA'),(10000, 'AAAAAAAACAAAAAAA'); -- Create the tpcds.customer_address_p1 table. openGauss=# CREATE TABLE tpcds.customer_address_p1 AS TABLE tpcds.customer_address; -- Change the value of explain_perf_mode to normal. openGauss=# SET explain_perf_mode=normal; -- Display an execution plan for simple queries in the table. openGauss=# 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). openGauss=# 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 datanodes" + } + } + ] (1 row) -- If there is an index and we use a query with an indexable WHERE condition, a different plan may be displayed. openGauss=# 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). openGauss=# 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) -- Here is an example of a query plan with cost estimates suppressed: openGauss=# 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) -- Here is an example of a query plan for a query using an aggregate function: openGauss=# 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 datanodes -> 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) -- Drop the tpcds.customer_address_p1 table. openGauss=# DROP TABLE tpcds.customer_address_p1; -- Drop the tpcds.customer_address table. openGauss=# DROP TABLE tpcds.customer_address; -- Drop the schema. openGauss=# DROP SCHEMA tpcds CASCADE; |
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