Understanding Explain Plans in Oracle 8i
In any relational database, the explain plan shows which way the database will access the data. In this article, Oracle expert Dan Hotka explores how understanding the explain plan can help you retrieve the right data from your Oracle database.
This article is adapted from Oracle8i from Scratch (Que, 2000, ISBN 0789723697).
In any relational database, the explain plan is the vehicle used to see which way the database will access the data. SQL statement tuning requires an understanding of explain plans. This article will help you understand the various parts of the explain plan and help you choose the best method for retrieving data from your Oracle database.
Oracle tools include TKPROF (which examines TRACE files), and the EXPLAIN command, combined with a SQL statement to display the results. Many third-party tools are available, such as Quest Software's SQLab, which assists the DBA with SQL explain-plan tuning, among other features.
The explain plan is a necessity for tuning SQL statements for both rule-based and cost-based optimizers. Listing 1 shows how to load the plan table and query the results. This plan table can then be set up for any user by running the $ORACLE_HOME/rdbms/admin/utlxplan.sql script from SQL*Plus.
The explain table in Listing 1 shows the Oracle explain plan for a simple SQL query. This explain plan is basically interpreted from the bottom up. Listing 2 shows output from the TKPROF (Oracle Trace Facility Analysis tool), which gives additional statistics over that of just the explain plan. Figure 1 shows the type of information available in a GUI tool. Notice that the same information is returned in the explain plan, but SQLab includes an explanation that assists you in understanding the steps, indents the explain steps (interpreted from indented steps out), can "walk" the order of execution of each step, and provides a host of other information and functionality.
Listing 1. Explain Plan Table and Results
SQL> EXPLAIN PLAN FOR 2 select ename 3 from emp 4 where deptno in (select deptno from dept where deptno = 10); Explained. SQL> SELECT operation, options, object_name, id, parent_id 2 from plan_table; OPERATION OPTIONS OBJECT_NAME ID PARENT_ID ---------------- ------------ ---------------- ---- --------- SELECT STATEMENT 0 NESTED LOOPS 1 0 INDEX UNIQUE SCAN PK_DEPT 2 1 TABLE ACCESS FULL EMP 3 1
Listing 2. TKPROF Output Example
select * from tutorial.cur_emp_status call count cpu elapsed disk query current rows ------- ------ -------- ---------- ------- ---------- --------- ------ Parse 1 0.02 0.02 0 0 0 0 Execute 1 0.00 0.00 0 0 0 0 Fetch 2 0.23 0.25 11 1051 3 15 ------- ------ -------- ---------- ------- ---------- --------- ------ total 4 0.25 0.27 11 1051 3 15
SQLab/Xpert explain plan and results.
Explain plans can be difficult to interpret. Table 1 describes the more common explain plan steps.
Table 1 Explain Plan Steps
Access Rule |
Description |
AND-EQUAL |
Index values will be used to join rows. |
CONCATENATION |
SQL statement UNION command. |
FILTER |
FILTERs apply "other criteria" in the query to further qualify the matching rows. The "other criteria" include correlated subqueries and the HAVING clause. |
FIRST ROW |
SQL statement will be processed via a cursor. |
FOR UPDATE |
SQL statement clause for update of placed row-level locks on affected rows. |
INDEX (UNIQUE) |
SQL statement utilized a unique index to search for a specific value. |
INDEX (RANGE SCAN) |
SQL statement contains a nonequality or BETWEEN condition. |
HASH JOIN |
SQL statement initiated a hash-join operation. |
MERGE JOIN |
SQL statement references two or more tables, sorting the two result sets being joined over the join columns and then merging the results via the join columns. |
NESTED LOOPS |
This operation is one form of joining tables, as opposed to a merge join. One row is retrieved from the row source identified by the first child operation, and then joined to all matching rows in the other table, identified in the second child operation. |
NONUNIQUE INDEX (RANGE SCAN) |
The RANGE SCAN option indicates that Oracle expects to return multiple matches (ROWIDs) from the index search. |
PARTITION (CONCATENATED) |
SQL statement will access a partitioned object and merge the retrieved rows from the accessed partitions. |
PARTITION (SINGLE) |
SQL statement will access a single partition. |
PARTITION (EMPTY) |
The SQL statement makes reference to an empty partition. |
SORT (ORDER BY) |
SQL statement contains an ORDER BY SQL command. |
SORT (AGREGATE) |
SQL statement initiated a sort to resolve a MIN or MAX type function. |
SORT (GROUP BY) |
SQL statement contains a GROUP BY SQL command. |
TABLE ACCESS (FULL) |
All rows are retrieved from the table without using an index. |
TABLE ACCESS (BY ROWID) |
A row is retrieved from a table based on the ROWID of the row. |
TABLE ACCESS (CLUSTER) |
A row is retrieved from a table that's part of an indexed cluster. |
UNION |
SQL statement contains a DISTINCT SQL command. |
There are three kinds of join conditions: nested loops, merge join, and hash joins. Each has specific performance implications, and they should be used in different circumstances:
-
Nested loops work from one table (preferably the smaller of the two), looking up the join criteria in the larger table. It's helpful if the join column is indexed from the larger table. Nested loops are useful when joining a smaller table to a larger table.
-
Merge joins work by selecting the result set from each table and then merging these two (or more) results. Merge joins are useful when joining two relatively large tables of about the same size.
-
Hash joins read the smaller tables into a hash table in memory so the referenced records can be accessed quickly by the hash key. Hash joins are great in data warehouse scenarios, in which several smaller tables (with referential integrity defined) are being referenced in the same SQL query as a single larger or very large table.
Figure 2 shows the performance results of each kind of join. The nested loop performs very well on smaller amounts of data. The merge join starts out with more overhead but remains rather consistent. The hash join has initial overhead (of creating the hash tables), but performs rather well no matter how many rows are involved.
Join condition comparisons.
Oracle8 has introduced three new columns: partition_start, partition_stop, and partition_id. These three new fields aid in the tuning of SQL statements that access partitioned objects. The partition_start and partition_stop show the range of partitions affected by this explain step. The partition_id is the identification number for that particular explain step.
Finally, there are both good and poor ways to code SQL statements. Here are some guidelines for SQL statement coding that will help both the rule-based and the cost-based optimizers:
-
DON'T use calculations in the where clause on indexed columns unless the intended behavior is to disable the index; any function on indexed columns will ignore the index.
-
DO use the IN operator instead of NOT. Try to avoid using the NOT command by using >=, <=, etc.
-
DON'T use an index if more than 20% of the rows will be returned by the query.
-
DO use array processing whenever possible (Export and Pro*C applications).
-
DON'T use subqueries if other solutions exist (PL/SQL loop, for example).
-
DO use hints to ensure the desired execution-plan results.
-
DON'T write applications that use SQL execution-plan defaults. Oracle makes no guarantees that default behavior will be maintained in future releases, or even between different hardware platforms.
About the Author
Dan Hotka is a director of database field operations for Quest Software. He has more than 22 years in the computer industry and more than 17 years of experience with Oracle products. He is an acknowledged Oracle expert, with Oracle experience dating back to the Oracle V4.0 days. He has just completed Oracle8i from Scratch (Que, 2000, ISBN 0789723697) and coauthored the popular books Oracle Unleashed (SAMS, 1996, 067230872X), Oracle8 Server Unleashed (SAMS, 1998, ISBN 0672312077), Oracle Development Unleashed, Third Edition (SAMS, 2000, ISBN 0672315750), and Special Edition Using Oracle8/8i (Que, 2000, ISBN 0789719754). Dan is frequently published in Oracle Professional, the monthly trade journal by Pinnacle Publications, and regularly speaks at Oracle conferences and usergroups around the world. Dan can be reached at dhotka@earthlink.net or dhotka@quest.com.