Except for singe run SQL (such as weekly reports
or infrequently used procedures) you should attempt to use bind
variables instead of literals in your PL/SQL code. Use of bind
variables allows the code to be reused multiple times. The entire
purpose of the shared pool is to allow reuse of SQL statements
that have already been parsed.
You can have the DBA set the CURSOR_SHARING
parameter to FORCED in Oracle8i or to FORCED or SIMILAR in
Oracle9i. In Oracle9i the hint CURSOR_SHARING_EXACT can be used
for specific code that shouldn't be shared. In Oracle8i there is
no CURSOR_SHARING_EXACT parameter and all literals in SELECT
statements will be changed to bind variables. In Oracle9i Oracle
uses bind variable peaking for the first time a SQL is parsed to
allow more optimal code paths to be selected.
It can be very difficult to pull your PL/SQL
procedure code out of the background code in an instance shared
pool. I suggest placing a comment in each SQL statement that
identifies the SQL within the shared pool. An example of this is:
Now to find all SQL code in the shared pool from
the DBA_UTILITIES package I can simply query the V$SQLAREA or
V$SQLTEXT to find code entries with '%DBA_UTIL%' in the SQL_TEXT
column.
There are many hints available to the developer
for use in tuning SQL statements that are embedded in PL/SQL. You
should first get the explain plan of your SQL and determine what
changes can be done to make the code operate without using hints
if possible. However, hints such as ORDERED, LEADING, INDEX, FULL,
and the various AJ and SJ hints can tame a wild optimizer and give
you optimal performance.
Hints are enclosed within comments to the SQL
commands DELETE, SELECT or UPDATE or are designated by two dashes
and a plus sign. To show the format the SELECT statement only will
be used, but the format is identical for all three commands.
The following table Shows the Oracle9i Hints and
their meanings.
Hint |
Meaning |
+ |
Must be immediately after comment indicator,
tells Oracle this is a list of hints. |
ALL_ROWS |
Use the cost based approach for best
throughput. |
CHOOSE |
Default, if statistics are available will use
cost, if not, rule. |
FIRST_ROWS |
Use the cost based approach for best response
time. |
RULE |
Use rules based approach; this cancels any
other hints specified for this statement. |
Access Method Hints: |
|
CLUSTER(table) |
This tells Oracle to do a cluster scan to
access the table |
FULL(table) |
This tells the optimizer to do a full scan of
the specified table. |
HASH(table) |
Tells Oracle to explicitly choose the hash
access method for the table. |
HASH_AJ(table) |
Transforms a NOT IN subquery to a hash
anti-join. |
ROWID(table) |
Forces a rowid scan of the specified table. |
INDEX(table [index]) |
Forces an index scan of the specified table
using the specified index(s). If a list of indexes is
specified, the optimizer chooses the one with the lowest cost.
If no index is specified then the optimizer chooses the
available index for the table with the lowest cost. |
INDEX_ASC (table [index]) |
Same as INDEX only performs an ascending
search of the index chosen, this is functionally identical to
the INDEX statement. |
INDEX_DESC(table [index]) |
Same as INDEX except performs a descending
search. If more than one table is accessed, this is ignored. |
INDEX_COMBINE(table index) |
Combines the bitmapped indexes on the table if
the cost shows that to do so would give better performance. |
INDEX_FFS(table index) |
Perform a fast full index scan rather than a
table scan. |
MERGE_AJ (table) |
Transforms a NOT IN subquery into a merge
anti-join. |
AND_EQUAL(table index index [index index
index]) |
This hint causes a merge on several single
column indexes. Two must be specified, five can be. |
NL_AJ |
Transforms a NOT IN subquery into a NL
anti-join (nested loop) |
HASH_SJ(t1, t2) |
Inserted into the EXISTS subquery; This
converts the subquery into a special type of hash join between
t1 and t2 that preserves the semantics of the subquery. That
is, even if there is more than one matching row in
t2 for a row in
t1 , the row in
t1 is returned
only once.
|
MERGE_SJ (t1, t2) |
Inserted into the EXISTS subquery; This
converts the subquery into a special type of merge join
between t1 and t2 that preserves the semantics of the subquery.
That is, even if there is more than one matching row in
t2 for a row in
t1 , the row in
t1 is returned
only once.
|
NL_SJ |
Inserted into the EXISTS subquery; This
converts the subquery into a special type of nested loop join
between t1 and t2 that preserves the semantics of the subquery.
That is, even if there is more than one matching row in
t2 for a row in
t1 , the row in
t1 is returned
only once.
|
Hints for join orders and transformations: |
|
ORDERED |
This hint forces tables to be joined in the
order specified. If you know table X has fewer rows, then
ordering it first may speed execution in a join. |
STAR |
Forces the largest table to be joined last
using a nested loops join on the index |
STAR_TRANSFORMATION |
Makes the optimizer use the best plan in which
a start transformation is used |
FACT(table) |
When performing a star transformation use the
specified table as a fact table |
NO_FACT(table) |
When performing a star transformation do not
use the specified table as a fact table |
PUSH_SUBQ |
This causes nonmerged subqueries to be
evaluated at the earliest possible point in the execution
plan. |
REWRITE(mview) |
If possible forces the query to use the
specified materialized view, if no materialized view is
specified, the system chooses what it calculates is the
appropriate view |
NOREWRITE |
Turns off query rewrite for the statement, use
it for when data returned must be concurrent and can't come
from a materialized view. |
USE_CONCAT |
Forces combined OR conditions and IN
processing in the WHERE clause to be transformed into a
compound query using the UNION ALL set operator. |
NO_MERGE (table) |
This causes Oracle to join each specified
table with another row source without a sort-merge join |
NO_EXPAND |
Prevents OR and IN processing expansion |
Hints for Join Operations: |
|
USE_HASH (table) |
This causes Oracle to join each specified
table with another row source with a hash join |
USE_NL(table) |
This operation forces a nested loop using the
specified table as the controlling table. |
USE_MERGE(table,[table,?]) |
This operation forces a sort-merge-join
operation of the specified tables. |
DRIVING_SITE |
The hint forces query execution to be done at
a different site than that selected by Oracle. This hint can
be used with either rule-based or cost-based optimization |
LEADING(table) |
The hint causes Oracle to use the specified
table as the first table in the join order. |
Hints for Parallel Operations: |
|
[NO]APPEND |
This specifies that data is to be or not to be
appended to the end of a file rather than into existing free
space. Use only with INSERT commands. |
NOPARALLEL (table) |
This specifies the operation is not to be done
in parallel. |
PARALLEL(table, instances) |
This specifies the operation is to be done in
parallel. |
PARALLEL_INDEX |
Allows parallelization of a fast full index
scan on any index. |
Other Hints: |
|
CACHE |
Specifies that the blocks retrieved for the
table in the hint are placed at the most recently used end of
the LRU list when the table is full table scanned. |
NOCACHE |
Specifies that the blocks retrieved for the
table in the hint are placed at the least recently used end of
the LRU list when the table is full table scanned. |
[NO]APPEND |
For insert operations will append (or not
append) data at the HWM of table. |
UNNEST |
Turns on the UNNEST_SUBQUERY option for
statement if UNNEST_SUBQUERY parameter is set to FALSE |
NO_UNNEST |
Turns off the UNNEST_SUBQUERY option for
statement if UNNEST_SUBQUERY parameter is set to TRUE |
PUSH_PRED |
Pushes the join predicate into the view |
NO_PUSH_PRED |
Forces the predicate not to be pushed into the
view |
ORDERED_PREDICATES |
The hint forces the optimizer to preserve the
order of predicate evaluation, except for predicates used as
index keys. Use this hint in the WHERE clause of SELECT
statements. |
CURSOR_SHARING_EXACT |
If the CURSOR_SHARING initialization parameter
is set to FORCE or SIMILAR, resets it to EXACT for this query
(no bind variable substitution) |
As you can see, a dilemma with a stubborn index
can be easily solved using FULL or NO_INDEX hints. You must know
the application to be tuned. The DBA can provide guidance to
developers but in all but the smallest development projects, it
will be nearly impossible for a DBA to know everything about each
application. It is clear that responsibility for application
tuning rests solely on the developer's shoulders with help and
guidance from the DBA.
While hints normally refer to table in the query
it is possible to specify a hint for a table within a view through
the use of what are known as GLOBAL HINTS. This is done using the
global hint syntax. Any table hint can be transformed into a
global hint.
If the view is an inline view, place an alias on
it and then use the alias to reference the inline view in the
global hint.
One problem I see a lot as a DBA is the over
specification of variable length in PL/SQL routines. Some
developers feel that since a VARCHAR2 can be up to 32k in PL/SQL
they should go ahead and specify the length to be many times what
they feel they need. An example is setting VARCHAR2 to 2000 when
you only need 80 characters.
The problem with over specifying variable size is
that the PL/SQL engine believes you and reserves the memory size
you ask for in each variable declaration. Now this may not be a
problem with one or two over specified variables but if this is a
PL/SQL table containing a thousand records in can place
considerable memory overhead on your system.