STL_PLAN_INFO
Use the STL_PLAN_INFO view to look at the EXPLAIN output for a query in terms of a set of rows. This is an alternative way to look at query plans.
STL_PLAN_INFO 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.
Note
STL_PLAN_INFO only contains queries run on main provisioned clusters. It doesn't contain queries run on concurrency scaling clusters or on serverless namespaces. To access explain plans for queries run on both main clusters, concurrency scaling clusters, and serverless namespaces, we recommend that you use the SYS monitoring view SYS_QUERY_DETAIL . The data in the SYS monitoring view is formatted to be easier to use and understand.
Table columns
Column name | Data type | Description |
---|---|---|
userid | integer | ID of the user who generated the entry. |
query | integer | Query ID. The query column can be used to join other system tables and views. |
nodeid | integer | Plan node identifier, where a node maps to one or more steps in the execution of the query. |
segment | integer | Number that identifies the query segment. |
step | integer | Number that identifies the query step. |
locus | integer | Location where the step runs. 0 if on a compute node and 1 if on the leader node. |
plannode | integer | Enumerated value of the plan node. See the following table for enums for plannode. (The PLANNODE column in STL_EXPLAIN contains the plan node text.) |
startupcost | double precision | The estimated relative cost of returning the first row for this step. |
totalcost | double precision | The estimated relative cost of executing the step. |
rows | bigint | The estimated number of rows that will be produced by the step. |
bytes | bigint | The estimated number of bytes that will be produced by the step. |
Sample queries
The following examples compare the query plans for a simple SELECT query returned by using the EXPLAIN command and by querying the STL_PLAN_INFO view.
explain select * from category; QUERY PLAN ------------------------------------------------------------- XN Seq Scan on category (cost=0.00..0.11 rows=11 width=49) (1 row) select * from category; catid | catgroup | catname | catdesc -------+----------+-----------+-------------------------------------------- 1 | Sports | MLB | Major League Baseball 3 | Sports | NFL | National Football League 5 | Sports | MLS | Major League Soccer ... select * from stl_plan_info where query=256; query | nodeid | segment | step | locus | plannode | startupcost | totalcost | rows | bytes -------+--------+---------+------+-------+----------+-------------+-----------+------+------- 256 | 1 | 0 | 1 | 0 | 104 | 0 | 0.11 | 11 | 539 256 | 1 | 0 | 0 | 0 | 104 | 0 | 0.11 | 11 | 539 (2 rows)
In this example, PLANNODE 104 refers to the sequential scan of the CATEGORY table.
select distinct eventname from event order by 1; eventname ------------------------------------------------------------------------ .38 Special 3 Doors Down 70s Soul Jam A Bronx Tale ... explain select distinct eventname from event order by 1; QUERY PLAN ------------------------------------------------------------------------------------- XN Merge (cost=1000000000136.38..1000000000137.82 rows=576 width=17) Merge Key: eventname -> XN Network (cost=1000000000136.38..1000000000137.82 rows=576 width=17) Send to leader -> XN Sort (cost=1000000000136.38..1000000000137.82 rows=576 width=17) Sort Key: eventname -> XN Unique (cost=0.00..109.98 rows=576 width=17) -> XN Seq Scan on event (cost=0.00..87.98 rows=8798 width=17) (8 rows) select * from stl_plan_info where query=240 order by nodeid desc; query | nodeid | segment | step | locus | plannode | startupcost | totalcost | rows | bytes -------+--------+---------+------+-------+----------+------------------+------------------+------+-------- 240 | 5 | 0 | 0 | 0 | 104 | 0 | 87.98 | 8798 | 149566 240 | 5 | 0 | 1 | 0 | 104 | 0 | 87.98 | 8798 | 149566 240 | 4 | 0 | 2 | 0 | 117 | 0 | 109.975 | 576 | 9792 240 | 4 | 0 | 3 | 0 | 117 | 0 | 109.975 | 576 | 9792 240 | 4 | 1 | 0 | 0 | 117 | 0 | 109.975 | 576 | 9792 240 | 4 | 1 | 1 | 0 | 117 | 0 | 109.975 | 576 | 9792 240 | 3 | 1 | 2 | 0 | 114 | 1000000000136.38 | 1000000000137.82 | 576 | 9792 240 | 3 | 2 | 0 | 0 | 114 | 1000000000136.38 | 1000000000137.82 | 576 | 9792 240 | 2 | 2 | 1 | 0 | 123 | 1000000000136.38 | 1000000000137.82 | 576 | 9792 240 | 1 | 3 | 0 | 0 | 122 | 1000000000136.38 | 1000000000137.82 | 576 | 9792 (10 rows)