Oracle® Database Performance Tuning Guide 10g Release 2 (10.2) Part Number B14211-03 |
|
|
View PDF |
Optimizer hints can be used with SQL statements to alter execution plans. This chapter explains how to use hints to instruct the optimizer to use specific approaches.
The chapter contains the following sections:
Hints let you make decisions usually made by the optimizer. As an application designer, you might know information about your data that the optimizer does not know. Hints provide a mechanism to instruct the optimizer to choose a certain query execution plan based on the specific criteria.
For example, you might know that a certain index is more selective for certain queries. Based on this information, you might be able to choose a more efficient execution plan than the optimizer. In such a case, use hints to instruct the optimizer to use the optimal execution plan.
Note:
The use of hints involves extra code that must be managed, checked, and controlled.Hints can be of the following general types:
Single-table
Single-table hints are specified on one table or view. INDEX
and USE_NL
are examples of single-table hints.
Multi-table
Multi-table hints are like single-table hints, except that the hint can specify one or more tables or views. LEADING
is an example of a multi-table hint. Note that USE_NL(table1 table2)
is not considered a multi-table hint because it is actually a shortcut for USE_NL(table1)
and USE_NL(table2)
.
Query block
Query block hints operate on single query blocks. STAR_TRANSFORMATION
and UNNEST
are examples of query block hints.
Statement
Statement hints apply to the entire SQL statement. ALL_ROWS
is an example of a statement hint.
Optimizer hints are grouped into the following categories:
These categories, and the hints contained within each category, are listed in the sections that follow.
See Also:
Oracle Database SQL Language Reference for syntax and a more detailed description of each hintThe following hints let you choose between optimization approaches and goals:
If a SQL statement has a hint specifying an optimization approach
and goal, then the optimizer uses the specified approach regardless of
the presence or absence of statistics, the value of the OPTIMIZER_MODE
initialization parameter, and the OPTIMIZER_MODE
parameter of the ALTER
SESSION
statement.
Note:
The optimizer goal applies only to queries submitted directly. Use hints to specify the access path for any SQL statements submitted from within PL/SQL. TheALTER
SESSION
... SET
OPTIMIZER_MODE
statement does not affect SQL that is run from within PL/SQL.If you specify either the ALL_ROWS
or the FIRST_ROWS
(n
)
hint in a SQL statement, and if the data dictionary does not have
statistics about tables accessed by the statement, then the optimizer
uses default statistical values, such as allocated storage for such
tables, to estimate the missing statistics and to subsequently choose
an execution plan. These estimates might not be as accurate as those
gathered by the DBMS_STATS
package, so you should use the DBMS_STATS
package to gather statistics.
If you specify hints for access paths or join operations along with either the ALL_ROWS
or FIRST_ROWS
(n
) hint, then the optimizer gives precedence to the access paths and join operations specified by the hints.
See "Optimization Approaches and Goal Hints in Views" for hint behavior with mergeable views.
Each of the following hints instructs the optimizer to use a specific access path for a table:
Specifying one of these hints causes the optimizer to choose the specified access path only if the access path is available based on the existence of an index or cluster and on the syntactic constructs of the SQL statement. If a hint specifies an unavailable access path, then the optimizer ignores it.
You must specify the table to be accessed exactly as it appears in the statement. If the statement uses an alias for the table, then use the alias rather than the table name in the hint. The table name within the hint should not include the schema name if the schema name is present in the statement.
See "Access Path and Join Hints on Views" and "Access Path and Join Hints Inside Views" for hint behavior with mergeable views.
Note:
For access path hints, Oracle ignores the hint if you specify theSAMPLE
option in the FROM
clause of a SELECT
statement.Each of the following hints instructs the optimizer to use a specific SQL query transformation:
Each of the following hints instructs the optimizer to use a specific join operation for a table:
Use of the USE_NL
and USE_MERGE
hints is recommended with any join order hint. See "Hints for Join Orders".
Oracle uses these hints when the referenced table is forced to be the
inner table of a join; the hints are ignored if the referenced table is
the outer table.
See "Access Path and Join Hints on Views" and "Access Path and Join Hints Inside Views" for hint behavior with mergeable views.
The hints that follow instruct the optimizer about how statements are parallelized or not parallelized when using parallel execution:
See "Parallel Execution Hints on Views" and "Parallel Execution Hints Inside Views" for hint behavior with mergeable views.
See Also:
Oracle Database Data Warehousing Guide for more information on parallel executionThe following are several additional hints:
Hints apply only to the optimization of the block of a statement in which they appear. A statement block is any one of the following statements or parts of statements:
A simple SELECT
, UPDATE
, or DELETE
statement
A parent statement or subquery of a complex statement
A part of a compound query
For example, a compound query consisting of two component queries combined by the UNION
operator has two blocks, one for each component query. For this reason,
hints in the first component query apply only to its optimization, not
to the optimization of the second component query.
The following sections discuss the use of hints in more detail.
When using hints, in some cases, you might need to specify a full
set of hints in order to ensure the optimal execution plan. For
example, if you have a very complex query, which consists of many table
joins, and if you specify only the INDEX
hint for a given
table, then the optimizer needs to determine the remaining access paths
to be used, as well as the corresponding join methods. Therefore, even
though you gave the INDEX
hint, the optimizer might not
necessarily use that hint, because the optimizer might have determined
that the requested index cannot be used due to the join methods and
access paths selected by the optimizer.
In Example 16-1, the LEADING
hint specifies the exact join order to be used; the join methods to be used on the different tables are also specified.
Example 16-1 Specifying a Full Set of Hints
SELECT /*+ LEADING(e2 e1) USE_NL(e1) INDEX(e1 emp_emp_id_pk) USE_MERGE(j) FULL(j) */ e1.first_name, e1.last_name, j.job_id, sum(e2.salary) total_sal FROM employees e1, employees e2, job_history j WHERE e1.employee_id = e2.manager_id AND e1.employee_id = j.employee_id AND e1.hire_date = j.start_date GROUP BY e1.first_name, e1.last_name, j.job_id ORDER BY total_sal;
To
identify a query block in a query, an optional query block name can be
used in a hint to specify the query block to which the hint applies.
The syntax of the query block argument is of the form @
queryblock
, where queryblock
is an identifier that specifies a query block in the query. The queryblock
identifier can either be system-generated or user-specified.
The system-generated identifier can be obtained by using EXPLAIN
PLAN
for the query. Pre-transformation query block names can be determined by running EXPLAIN
PLAN
for the query using the NO_QUERY_TRANSFORMATION
hint.
The user-specified name can be set with the QB_NAME
hint.
In Example 16-2, the query block name is used with the NO_UNNEST
hint to specify a query block in a SELECT statement on the view.
Example 16-2 Using a Query Block in a Hint
CREATE OR REPLACE VIEW v AS SELECT e1.first_name, e1.last_name, j.job_id, sum(e2.salary) total_sal FROM employees e1, ( SELECT * FROM employees e3) e2, job_history j WHERE e1.employee_id = e2.manager_id AND e1.employee_id = j.employee_id AND e1.hire_date = j.start_date AND e1.salary = ( SELECT max(e2.salary) FROM employees e2 WHERE e2.department_id = e1.department_id ) GROUP BY e1.first_name, e1.last_name, j.job_id ORDER BY total_sal;
After running EXPLAIN
PLAN
for the query
and displaying the plan table output, you can determine the
system-generated query block identifier. For example, a query block
name is displayed in the following plan table output:
SELECT PLAN_TABLE_OUTPUT FROM TABLE(DBMS_XPLAN.DISPLAY(NULL, NULL, 'SERIAL'));
...
Query Block Name / Object Alias (identified by operation id):
-------------------------------------------------------------
...
10 - SEL$4 / E2@SEL$4
After the query block name is determined it can be used in the following SQL statement:
SELECT /*+ NO_UNNEST( @SEL$4 ) */
*
FROM v;
Hints that specify a table generally refer to tables in the DELETE
, SELECT
, or UPDATE
query block in which the hint occurs, not to tables inside any views
referenced by the statement. When you want to specify hints for tables
that appear inside views, Oracle recommends using global
hints instead of embedding the hint in the view. Table hints described
in this chapter can be transformed into a global hint by using an extended tablespec
syntax that includes view names with the table name.
In addition, an optional query block name can precede the tablespec
syntax. See "Specifying a Query Block in a Hint".
Hints that specify a table use the following syntax:
tablespec::=
Description of the illustration tablespec.gif
where:
view
specifies a view name
table
specifies the name or alias of the table
If the view path is specified, the hint is resolved from left to right, where the first view must be present in the FROM
clause, and each subsequent view must be specified in the FROM
clause of the preceding view.
For example, in Example 16-3 a view v
is created to return the first and last name of the employee, his or
her first job and the total salary of all direct reports of that
employee for each employee with the highest salary in his or her
department. When querying the data, you want to force the use of the
index emp_job_ix
for the table e3
in view e2
.
Example 16-3 Using Global Hints Example
CREATE OR REPLACE VIEW v AS SELECT e1.first_name, e1.last_name, j.job_id, sum(e2.salary) total_sal FROM employees e1, ( SELECT * FROM employees e3) e2, job_history j WHERE e1.employee_id = e2.manager_id AND e1.employee_id = j.employee_id AND e1.hire_date = j.start_date AND e1.salary = ( SELECT max(e2.salary) FROM employees e2 WHERE e2.department_id = e1.department_id) GROUP BY e1.first_name, e1.last_name, j.job_id ORDER BY total_sal;
By using the global hint structure, you can avoid the modification of view v
with the specification of the index hint in the body of view e2
. To force the use of the index emp_job_ix
for the table e3
, you can use one of the following:
SELECT /*+ INDEX(v.e2.e3 emp_job_ix) */ * FROM v; SELECT /*+ INDEX(@SEL$2 e2.e3 emp_job_ix) */ * FROM v; SELECT /*+ INDEX(@SEL$3 e3 emp_job_ix) */ * FROM v;
The global hint syntax also applies to unmergeable views as in Example 16-4.
Example 16-4 Using Global Hints with NO_MERGE
CREATE OR REPLACE VIEW v1 AS SELECT * FROM employees WHERE employee_id < 150; CREATE OR REPLACE VIEW v2 AS SELECT v1.employee_id employee_id, departments.department_id department_id FROM v1, departments WHERE v1.department_id = departments.department_id; SELECT /*+ NO_MERGE(v2) INDEX(v2.v1.employees emp_emp_id_pk) FULL(v2.departments) */ * FROM v2 WHERE department_id = 30;
The hints cause v2
not to be merged and specify access
path hints for the employee and department tables. These hints are
pushed down into the (nonmerged) view v2
.
See Also:
"Using Hints with Views"Hints that specify an index can use either a simple index name or a parenthesized list of columns as follows:
indexspec::=
where:
table
specifies the name
column
specifies the name of a column in the specified table
The columns can optionally be prefixed with table qualifiers allowing the hint to specify bitmap join indexes where the index columns are on a different table than the indexed table. If tables qualifiers are present, they must be base tables, not aliases in the query.
Each column in an index specification must be a base column in the specified table, not an expression. Function-based indexes cannot be hinted using a column specification unless the columns specified in the index specification form the prefix of a function-based index.
index
specifies an index name
The hint is resolved as follows:
If an index name is specified, only that index is considered.
If a column list is specified and an index exists whose columns match the specified columns in number and order, only that index is considered. If no such index exists, then any index on the table with the specified columns as the prefix in the order specified is considered. In either case, the behavior is exactly as if the user had specified the same hint individually on all the matching indexes.
For example, in Example 16-3 the job_history
table has a single-column index on the employee_id
column and a concatenated index on employee_id
and start_date
columns. To specifically instruct the optimizer on index use, the query can be hinted as follows:
SELECT /*+ INDEX(v.j jhist_employee_ix (employee_id start_date)) */ * FROM v;
Oracle does not encourage the use of hints inside or on views (or subqueries). This is because you can define views in one context and use them in another. Also, such hints can result in unexpected execution plans. In particular, hints inside views or on views are handled differently, depending on whether the view is mergeable into the top-level query.
If you want to specify a hint for a table in a view or subquery, then the global hint syntax is recommended. See "Specifying Global Table Hints".
If you decide, nonetheless, to use hints with views, the following sections describe the behavior in each case.
By default, hints do not propagate inside a complex view. For example, if you specify a hint in a query that selects against a complex view, then that hint is not honored, because it is not pushed inside the view.
Note:
If the view is a single-table, then the hint is not propagated.Unless the hints are inside the base view, they might not be honored from a query against the view.
This section describes hint behavior with mergeable views.
Optimization Approaches and Goal Hints in Views
Optimization approach and goal hints can occur in a top-level query or inside views.
If there is such a hint in the top-level query, then that hint is used regardless of any such hints inside the views.
If there is no top-level optimizer mode hint, then mode hints in referenced views are used as long as all mode hints in the views are consistent.
If two or more mode hints in the referenced views conflict, then all mode hints in the views are discarded and the session mode is used, whether default or user-specified.
Access Path and Join Hints on Views
Access path and join hints on referenced views are ignored, unless the view contains a single table (or references an Additional Hints view with a single table). For such single-table views, an access path hint or a join hint on the view applies to the table inside the view.
Access Path and Join Hints Inside Views
Access path and join hints can appear in a view definition.
If the view is an inline view (that is, if it appears in the FROM
clause of a SELECT
statement), then all access path and join hints inside the view are preserved when the view is merged with the top-level query.
For views that are non-inline views, access path and join hints in
the view are preserved only if the referencing query references no
other tables or views (that is, if the FROM
clause of the SELECT
statement contains only the view).
Parallel Execution Hints on Views
PARALLEL
, NO_PARALLEL
, PARALLEL_INDEX
, and NO_PARALLEL_INDEX
hints on views are applied recursively to all the tables in the
referenced view. Parallel execution hints in a top-level query override
such hints inside a referenced view.
Parallel Execution Hints Inside Views
PARALLEL
, NO_PARALLEL
, PARALLEL_INDEX
, and NO_PARALLEL_INDEX
hints inside views are preserved when the view is merged with the
top-level query. Parallel execution hints on the view in a top-level
query override such hints inside a referenced view.
With nonmergeable views, optimization approach and goal hints inside the view are ignored; the top-level query decides the optimization mode.
Because nonmergeable views are optimized separately from the top-level query, access path and join hints inside the view are preserved. For the same reason, access path hints on the view in the top-level query are ignored.
However, join hints on the view in the top-level query are preserved because, in this case, a nonmergeable view is similar to a table.