More cursor-related details in the plan output
Dmitry Yemanov
Tracker ticket: #7441
Detailed plan output now distinguishes between user-specified SELECT statements (reported as select expressions), PSQL declared cursors and sub-queries.Both legacy and detailed plans now also include information about cursor’s position (line/column) inside their PSQL module.
Examples:
-- line 23, column 2 PLAN (DISTRICT INDEX (DISTRICT_PK)) -- line 28, column 2 PLAN JOIN (CUSTOMER INDEX (CUSTOMER_PK), WAREHOUSE INDEX(WAREHOUSE_PK))
Select Expression (line 23, column 2)
-> Singularity Check
-> Filter
-> Table "DISTRICT" Access By ID
-> Bitmap
-> Index "DISTRICT_PK" Unique Scan
Select Expression (line 28, column 2)
-> Singularity Check
-> Nested Loop Join (inner)
-> Filter
-> Table "CUSTOMER" Access By ID
-> Bitmap
-> Index "CUSTOMER_PK" Unique Scan
-> Filter
-> Table "WAREHOUSE" Access By ID
-> Bitmap
-> Index "WAREHOUSE_PK" Unique Scan
Line/column numbers (as well as PSQL declared cursors) cannot be seen directly in the plan for user-specified SQL queries, except if the query is EXECUTE BLOCK.However, they are accessible in the MON$EXPLAINED_PLAN column in either MON$STATEMENTS or MON$COMPILED_STATEMENTS tables.