Home > Articles > Data > Oracle

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.

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

Figure 1

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.

Figure 2

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.

InformIT Promotional Mailings & Special Offers

I would like to receive exclusive offers and hear about products from InformIT and its family of brands. I can unsubscribe at any time.

Overview


Pearson Education, Inc., 221 River Street, Hoboken, New Jersey 07030, (Pearson) presents this site to provide information about products and services that can be purchased through this site.

This privacy notice provides an overview of our commitment to privacy and describes how we collect, protect, use and share personal information collected through this site. Please note that other Pearson websites and online products and services have their own separate privacy policies.

Collection and Use of Information


To conduct business and deliver products and services, Pearson collects and uses personal information in several ways in connection with this site, including:

Questions and Inquiries

For inquiries and questions, we collect the inquiry or question, together with name, contact details (email address, phone number and mailing address) and any other additional information voluntarily submitted to us through a Contact Us form or an email. We use this information to address the inquiry and respond to the question.

Online Store

For orders and purchases placed through our online store on this site, we collect order details, name, institution name and address (if applicable), email address, phone number, shipping and billing addresses, credit/debit card information, shipping options and any instructions. We use this information to complete transactions, fulfill orders, communicate with individuals placing orders or visiting the online store, and for related purposes.

Surveys

Pearson may offer opportunities to provide feedback or participate in surveys, including surveys evaluating Pearson products, services or sites. Participation is voluntary. Pearson collects information requested in the survey questions and uses the information to evaluate, support, maintain and improve products, services or sites, develop new products and services, conduct educational research and for other purposes specified in the survey.

Contests and Drawings

Occasionally, we may sponsor a contest or drawing. Participation is optional. Pearson collects name, contact information and other information specified on the entry form for the contest or drawing to conduct the contest or drawing. Pearson may collect additional personal information from the winners of a contest or drawing in order to award the prize and for tax reporting purposes, as required by law.

Newsletters

If you have elected to receive email newsletters or promotional mailings and special offers but want to unsubscribe, simply email information@informit.com.

Service Announcements

On rare occasions it is necessary to send out a strictly service related announcement. For instance, if our service is temporarily suspended for maintenance we might send users an email. Generally, users may not opt-out of these communications, though they can deactivate their account information. However, these communications are not promotional in nature.

Customer Service

We communicate with users on a regular basis to provide requested services and in regard to issues relating to their account we reply via email or phone in accordance with the users' wishes when a user submits their information through our Contact Us form.

Other Collection and Use of Information


Application and System Logs

Pearson automatically collects log data to help ensure the delivery, availability and security of this site. Log data may include technical information about how a user or visitor connected to this site, such as browser type, type of computer/device, operating system, internet service provider and IP address. We use this information for support purposes and to monitor the health of the site, identify problems, improve service, detect unauthorized access and fraudulent activity, prevent and respond to security incidents and appropriately scale computing resources.

Web Analytics

Pearson may use third party web trend analytical services, including Google Analytics, to collect visitor information, such as IP addresses, browser types, referring pages, pages visited and time spent on a particular site. While these analytical services collect and report information on an anonymous basis, they may use cookies to gather web trend information. The information gathered may enable Pearson (but not the third party web trend services) to link information with application and system log data. Pearson uses this information for system administration and to identify problems, improve service, detect unauthorized access and fraudulent activity, prevent and respond to security incidents, appropriately scale computing resources and otherwise support and deliver this site and its services.

Cookies and Related Technologies

This site uses cookies and similar technologies to personalize content, measure traffic patterns, control security, track use and access of information on this site, and provide interest-based messages and advertising. Users can manage and block the use of cookies through their browser. Disabling or blocking certain cookies may limit the functionality of this site.

Do Not Track

This site currently does not respond to Do Not Track signals.

Security


Pearson uses appropriate physical, administrative and technical security measures to protect personal information from unauthorized access, use and disclosure.

Children


This site is not directed to children under the age of 13.

Marketing


Pearson may send or direct marketing communications to users, provided that

  • Pearson will not use personal information collected or processed as a K-12 school service provider for the purpose of directed or targeted advertising.
  • Such marketing is consistent with applicable law and Pearson's legal obligations.
  • Pearson will not knowingly direct or send marketing communications to an individual who has expressed a preference not to receive marketing.
  • Where required by applicable law, express or implied consent to marketing exists and has not been withdrawn.

Pearson may provide personal information to a third party service provider on a restricted basis to provide marketing solely on behalf of Pearson or an affiliate or customer for whom Pearson is a service provider. Marketing preferences may be changed at any time.

Correcting/Updating Personal Information


If a user's personally identifiable information changes (such as your postal address or email address), we provide a way to correct or update that user's personal data provided to us. This can be done on the Account page. If a user no longer desires our service and desires to delete his or her account, please contact us at customer-service@informit.com and we will process the deletion of a user's account.

Choice/Opt-out


Users can always make an informed choice as to whether they should proceed with certain services offered by InformIT. If you choose to remove yourself from our mailing list(s) simply visit the following page and uncheck any communication you no longer want to receive: www.informit.com/u.aspx.

Sale of Personal Information


Pearson does not rent or sell personal information in exchange for any payment of money.

While Pearson does not sell personal information, as defined in Nevada law, Nevada residents may email a request for no sale of their personal information to NevadaDesignatedRequest@pearson.com.

Supplemental Privacy Statement for California Residents


California residents should read our Supplemental privacy statement for California residents in conjunction with this Privacy Notice. The Supplemental privacy statement for California residents explains Pearson's commitment to comply with California law and applies to personal information of California residents collected in connection with this site and the Services.

Sharing and Disclosure


Pearson may disclose personal information, as follows:

  • As required by law.
  • With the consent of the individual (or their parent, if the individual is a minor)
  • In response to a subpoena, court order or legal process, to the extent permitted or required by law
  • To protect the security and safety of individuals, data, assets and systems, consistent with applicable law
  • In connection the sale, joint venture or other transfer of some or all of its company or assets, subject to the provisions of this Privacy Notice
  • To investigate or address actual or suspected fraud or other illegal activities
  • To exercise its legal rights, including enforcement of the Terms of Use for this site or another contract
  • To affiliated Pearson companies and other companies and organizations who perform work for Pearson and are obligated to protect the privacy of personal information consistent with this Privacy Notice
  • To a school, organization, company or government agency, where Pearson collects or processes the personal information in a school setting or on behalf of such organization, company or government agency.

Links


This web site contains links to other sites. Please be aware that we are not responsible for the privacy practices of such other sites. We encourage our users to be aware when they leave our site and to read the privacy statements of each and every web site that collects Personal Information. This privacy statement applies solely to information collected by this web site.

Requests and Contact


Please contact us about this Privacy Notice or if you have any requests or questions relating to the privacy of your personal information.

Changes to this Privacy Notice


We may revise this Privacy Notice through an updated posting. We will identify the effective date of the revision in the posting. Often, updates are made to provide greater clarity or to comply with changes in regulatory requirements. If the updates involve material changes to the collection, protection, use or disclosure of Personal Information, Pearson will provide notice of the change through a conspicuous notice on this site or other appropriate way. Continued use of the site after the effective date of a posted revision evidences acceptance. Please contact us if you have questions or concerns about the Privacy Notice or any objection to any revisions.

Last Update: November 17, 2020