SYS_QUERY_EXPLAIN
Displays the EXPLAIN plan for a query that has been submitted for execution.
SYS_QUERY_EXPLAIN is visible to all users. Superusers can see all rows; regular users can see only their own data. For more information, see Visibility of data in system tables and views.
Table columns
Column name | Data type | Description |
---|---|---|
user_id | integer | The identifier of the user who submitted the query. |
query_id | bigint | The query identifier. Detailed query information is stored in SYS_QUERY_HISTORY. |
child_query_sequence | integer | The sequence of the rewritten user query, starting with 1. |
plan_node_id | integer | The identifier of a plan node that maps to one or more steps in the query. |
plan_parent_id | integer | The identifier of the plan node's parent node. A parent node can have multiple child nodes. For example, a merge join is the parent node of the scans on the joined tables. |
plan_node | character(400) | The node text from the EXPLAIN output. Plan nodes that refer to execution on compute nodes are prefixed with XN in the EXPLAIN output. |
node_info | character(400) | Qualifier and filter information for the plan node. For example, join conditions and WHERE clause restrictions are included in this column. |
Sample queries
The following example is the EXPLAIN plan of a single query.
SELECT * FROM sys_query_explain WHERE query_id = 612635 ORDER_BY plan_node_id; userid | query_id | child_query_sequence | plan_node_id | plan_parent_id | plan_node | plan_info --------+----------+----------------------+--------------+----------------+------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------+------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------ 100 | 612635 | 1 | 1 | 0 | XN Limit (cost=3604047533041.00..3604047533041.25 rows=100 width=20) | 100 | 612635 | 1 | 2 | 1 | -> XN Merge (cost=3604047533041.00..3604047533148.02 rows=42809 width=20) | Merge Key: sum(b.totalprice) 100 | 612635 | 1 | 3 | 2 | -> XN Network (cost=3604047533041.00..3604047533148.02 rows=42809 width=20) | Send to leader 100 | 612635 | 1 | 4 | 3 | -> XN Sort (cost=3604047533041.00..3604047533148.02 rows=42809 width=20) | Sort Key: sum(b.totalprice) 100 | 612635 | 1 | 5 | 4 | -> XN HashAggregate (cost=2604047529640.76..2604047529747.78 rows=42809 width=20) | 100 | 612635 | 1 | 6 | 5 | -> XN Hash Join DS_DIST_NONE (cost=15104956.16..2602364653507.34 rows=336575226684 width=20) | Hash Cond: (("outer".listid = "inner".listid) AND ("outer".sellerid = "inner".sellerid)) 100 | 612635 | 1 | 7 | 6 | -> XN Seq Scan on listing b (cost=0.00..7884677.12 rows=788467712 width=24) | 100 | 612635 | 1 | 8 | 6 | -> XN Hash (cost=7063797.76..7063797.76 rows=706379776 width=8) | 100 | 612635 | 1 | 9 | 8 | -> XN Seq Scan on sales a (cost=0.00..7063797.76 rows=706379776 width=8) | (9 rows)