Displaying an execution plan is made easy if you use the DBMS_XPLAN package.
This packages provides several PL/SQL procedures to display the plan from different sources:
• EXPLAIN PLAN command
• V$SQL_PLAN
• Automatic Workload Repository (AWR)
• SQL Tuning Set (STS)
• SQL Plan Baseline (SPM)
The following examples illustrate how to generate and display an execution plan for our original SQL statement using the different functions provided in the dbms_xplan package.
Example 1: Uses the EXPLAIN PLAN command and the DBMS_XPLAN.DISPLAY function.
1 2 3 4 5 | SQL> EXPLAIN PLAN FOR select prod_category, avg(amount_sold) from sales s, products p where p.prod_id = s.prod_id group by prod_category; |
Explained.
1 | SQL> select plan_table_output from table(dbms_xplan.display('plan_table',null,'basic')); |
The arguments are for DBMS_XPLAN.DISPLAY are:
• Plan table name (default ‘PLAN_TABLE’)
• Statement_id (default NULL)
• Format (default ‘TYPICAL’)
More details can be found in $ORACLE_HOME/rdbms/admin/dbmsxpln.sql.
Example 2: Generating and displaying the execution plan for the last SQL statement executed in a session:
1 2 3 4 5 6 | SQL> select prod_category, avg(amount_sold) from sales s, products p where p.prod_id = s.prod_id group by prod_category; no rows selected |
1 2 3 4 5 6 7 8 9 10 11 12 13 | SQL> select plan_table_output from table(dbms_xplan.display_cursor(null,null,'basic')); ------------------------------------------ Id Operation Name ------------------------------------------ 0 SELECT STATEMENT 1 HASH GROUP BY 2 HASH JOIN 3 TABLE ACCESS FULL PRODUCTS 4 PARTITION RANGE ALL 5 TABLE ACCESS FULL SALES ------------------------------------------ |
The arguments used by DBMS_XPLAN.DISPLAY_CURSOR are:
• SQL ID (default NULL, which means the last SQL statement executed in this session)
• Child number (default 0)
• Format (default ‘TYPICAL’)
The details are in $ORACLE_HOME/rdbms/admin/dbmsxpln.sql.
Example 3: Displaying the execution plan for any other statement requires the SQL ID to be provided, either directly or indirectly:
Directly:
1 2 | SQL> select plan_table_output from table(dbms_xplan.display_cursor('fnrtqw9c233tt',null,'basic')); |
Indirectly:
1 2 3 4 5 | SQL> select plan_table_output from v$sql s, table(dbms_xplan.display_cursor(s.sql_id, s.child_number, 'basic')) t where s.sql_text like 'select PROD_CATEGORY%'; |
Example 4: Displaying an execution plan corresponding to a SQL Plan Baseline.
1 2 3 | SQL> alter session set optimizer_capture_sql_plan_baselines=true; Session altered. |
1 2 3 4 5 6 | SQL> select prod_category, avg(amount_sold) from sales s, products p where p.prod_id = s.prod_id group by prod_category; no rows selected |
If the above statement has been executed more than once, a SQL Plan Baseline will be created for it and you can verified this using the follows query:
1 2 3 4 5 6 7 | SQL> select SQL_HANDLE, PLAN_NAME, ACCEPTED from dba_sql_plan_baselines where sql_text like 'select prod_category%'; SQL_HANDLE PLAN_NAME ACC ------------------------------ ------------------------------ --- SYS_SQL_1899bb9331ed7772 SYS_SQL_PLAN_31ed7772f2c7a4c2 YES |
The execution plan for the SQL Plan Baseline created above can be displayed either directly or indirectly:
Directly:
1 2 3 | select t.* from table(dbms_xplan.display_sql_plan_baseline('SYS_SQL_1899bb9331ed7772', format => 'basic')) t |
Indirectly:
1 2 3 4 5 6 | select t.* from (select distinct sql_handle from dba_sql_plan_baselines where sql_text like 'select prod_category%') pb, table(dbms_xplan.display_sql_plan_baseline(pb.sql_handle, null,'basic')) t; |
The output of either of these two statements is:
1 2 3 4 5 6 7 8 9 10 11 12 13 14 15 16 17 18 19 20 21 22 23 | ---------------------------------------------------------------------------- SQL handle: SYS_SQL_1899bb9331ed7772 SQL text: select prod_category, avg(amount_sold) from sales s, products p where p.prod_id = s.prod_id group by prod_category ---------------------------------------------------------------------------- ---------------------------------------------------------------------------- Plan name: SYS_SQL_PLAN_31ed7772f2c7a4c2 Enabled: YES Fixed: NO Accepted: YES Origin: AUTO-CAPTURE ---------------------------------------------------------------------------- Plan hash value: 4073170114 --------------------------------------------------------- Id Operation Name --------------------------------------------------------- 0 SELECT STATEMENT 1 HASH GROUP BY 2 HASH JOIN 3 VIEW index$_join$_002 4 HASH JOIN 5 INDEX FAST FULL SCAN PRODUCTS_PK 6 INDEX FAST FULL SCAN PRODUCTS_PROD_CAT_IX 7 PARTITION RANGE ALL 8 TABLE ACCESS FULL SALES --------------------------------------------------------- |
Formatting
The format argument is highly customizable and allows you to see as little (high-level) or as much (low-level) details as you need / want in the plan output. The high-level options are:
1. Basic
The plan includes the operation, options, and the object name (table, index, MV, etc)
2. Typical
It includes the information shown in BASIC plus additional optimizer-related internal information such as cost, size, cardinality, etc.
These information are shown for every operation in the plan and represents what the optimizer thinks is the operation cost, the number of rows produced, etc.
It also shows the predicates evaluation by the operation. There are two types of predicates: ACCESS and FILTER.
The ACCESS predicates for an index are used to fetch the relevant blocks because they apply to the search columns.
The FILTER predicates are evaluated after the blocks have been fetched.
3. All
It includes the information shown in TYPICAL plus the lists of expressions (columns) produced by every operation, the hint alias and query block names where the operation belongs.
The last two pieces of information can be used as arguments to add hints to the statement.
The low-level options allow the inclusion or exclusion of find details, such as predicates and cost.
For example:
1 2 3 4 5 6 7 8 9 10 11 12 13 14 15 16 17 18 19 | select plan_table_output from table(dbms_xplan.display('plan_table',null,'basic +predicate +cost')); ------------------------------------------------------- Id Operation Name Cost (%CPU) ------------------------------------------------------- 0 SELECT STATEMENT 17 (18) 1 HASH GROUP BY 17 (18) * 2 HASH JOIN 15 (7) 3 TABLE ACCESS FULL PRODUCTS 9 (0) 4 PARTITION RANGE ALL 5 (0) 5 TABLE ACCESS FULL SALES 5 (0) ------------------------------------------------------- Predicate Information (identified by operation id): --------------------------------------------------- 2 - access("P"."PROD_ID"="S"."PROD_ID") select plan_table_output from table(dbms_xplan.display('plan_table',null,'typical -cost -bytes')); |
Note Section
In addition to the plan, the package displays notes in the NOTE section, such as that dynamic sampling was used during query optimization or that star transformation was applied to the query.
For example, if the table SALES did not have statistics then the optimizer will use dynamic sampling and the plan display will report it as follows (see s’+note’ detail in the query):
1 2 3 4 5 6 7 8 9 10 11 12 13 14 15 16 | select plan_table_output from table(dbms_xplan.display('plan_table',null,'basic +note')); ------------------------------------------ Id Operation Name ------------------------------------------ 0 SELECT STATEMENT 1 HASH GROUP BY 2 HASH JOIN 3 TABLE ACCESS FULL PRODUCTS 4 PARTITION RANGE ALL 5 TABLE ACCESS FULL SALES ------------------------------------------ Note ----- - dynamic sampling used for this statement |
Bind Peeking
The query optimizer takes into account the values of bind variable values when generation an execution plan.
It does what is generally called bind peeking. See the first post in this blog about the concept of bind peeking and its impact on the plans and the performance of SQL statements.
As stated earlier the plan shown in V$SQL_PLAN takes into account the values of bind variables while the one shown from using EXPLAIN PLAN does not.
The DBMS_XPLAN package allows the display of the bind variable values used to generate a particular cursor/plan.
This is done by adding ‘+peeked_binds’ to the format argument when using display_cursor().
This is illustrated with the following example:
1 2 3 4 5 6 7 8 9 10 11 12 13 14 15 16 17 18 19 20 21 22 23 24 | variable pcat varchar2(50) exec :pcat := 'Women' select PROD_CATEGORY, avg(amount_sold) from sales s, products p where p.PROD_ID = s.PROD_ID and prod_category != :pcat group by PROD_CATEGORY; select plan_table_output from table(dbms_xplan.display_cursor(null,null,'basic +PEEKED_BINDS')); ------------------------------------------ Id Operation Name ------------------------------------------ 0 SELECT STATEMENT 1 HASH GROUP BY 2 HASH JOIN 3 TABLE ACCESS FULL PRODUCTS 4 PARTITION RANGE ALL 5 TABLE ACCESS FULL SALES ------------------------------------------ Peeked Binds (identified by position): -------------------------------------- 1 - :PCAT (VARCHAR2(30), CSID=2): 'Women' |