 |
|
Administration of OUTLINE Objects
Oracle Database Tips by Donald Burleson |
An outline is a stored query path or set of
attributes that will be used by the optimizer to optimize a specific
SQL query. Outlines can be enabled or disabled at both the system and
session levels by use of the ALTER SESSION and ALTER SYSTEM commands.
An outline should not be generated until the statement to be outlined
has been tuned and you are absolutely sure that it is performing
exactly the way you want it to.
In order to create outlines, users must have
the CREATE ANY OUTLINE privilege; to create a clone of an existing
outline (in Oracle9i) users must have SELECT_CATALOG_ROLE granted.
Storing plan outlines for SQL statements is
known as plan stability; it ensures that changes in the Oracle
environment don't affect the way a SQL statement is optimized by the
cost-based optimizer. If you want, Oracle will define plans for
all issued SQL statements at the time they are executed, and this
stored plan will be reused until altered or dropped. Generally,
however, I do not suggest using the automatic outline feature as it
can lead to poor plans being reused by the optimizer. It makes more
sense to monitor for high-cost statements and tune them as required,
storing an outline for them only after they have been properly tuned.
As with the storage of SQL in the shared pool,
the storage of outlines depends on the statement being reissued in an
identical fashion each time it is used. If even one space is out of
place, the stored outline is not reused. Therefore, your queries
should be stored as PL/SQL procedures, functions, or packages (or
perhaps Java routines), and bind variables should always be used. This
allows reuse of the stored image of the SQL as well as reuse of stored
outlines.
Remember that to be useful over the life of an
application, the outlines will have to be periodically verified by
checking SQL statement performance. If performance of SQL statements
degrades, the stored outline may have to be dropped and regenerated
after the SQL is retuned.
In Oracle9i, the ability to edit a stored
outline is provided by means of the DBMS_OTLN_EDIT Oracle-provided
package.
You enable or disable the use of stored
outlines dynamically for an individual session or for the system:
* Enable the USE_STORED_OUTLINES parameter to
use public outlines.
* Enable the USE_PRIVATE_OUTLINES parameter to
use private stored outlines.
Creation of an OUTLINE Object
Outlines are created using the CREATE OUTLINE
command; the syntax for this command is:
CREATE [OR REPLACE] [PUBLIC|PRIVATE]
OUTLINE outline_name
[FROM [PUBLIC|PRIVATE] source_outline_name]
[FOR CATEGORY category_name]
ON statement;
where:
PUBLIC|PRIVATE. By default all outlines
are public. Before first creating a private outline, you must run the
DBMS_OUTLN_EDIT.CREATE_EDIT_TABLES procedure to create the
required outline tables and indexes in your schema.
Outline_name. A unique name for the
outline.
FROM. Use this clause to create a new
outline by copying an existing one. By default, Oracle looks for the
source category in the public area. If you specify PRIVATE, Oracle
will look for the outline in the current schema. If you specify the
FROM clause, you cannot specify the ON clause.
[FOR CATEGORY category_name].
(Optional) Allows more than one outline to be associated with a single
query by specifying multiple categories, each named uniquely.
ON statement. Specifies the statement
for which the outline is prepared.
An example would be:
CREATE OR
REPLACE PUBLIC OUTLINE get_tables
ON
SELECT
a.owner,
a.table_name,
a.tablespace_name,
SUM(b.bytes),
COUNT(b.table_name) extents
FROM
dba_tables a,
dba_extents b
WHERE
a.owner=b.owner
AND a.table_name=b.table_name
GROUP BY
a.owner, a.table_name, a.tablespace_name;
Assuming the above select is a part of a
stored PL/SQL procedure or perhaps part of a view, the stored outline
will now be used each time an exactly-matching SQL statement is
issued.
Before a public outline can be created, the
user must have access to a PLAN_TABLE.
Altering an OUTLINE Object
Outlines are altered using the ALTER OUTLINE
or the CREATE OR REPLACE form of the CREATE command. The format of the
command is identical whether it is used for the creation or
replacement of an existing outline. For example, assume we want to add
SUM(b.blocks) to the previous example.
CREATE OR
REPLACE PUBLIC OUTLINE get_tables
ON
SELECT
a.owner,
a.table_name,
a.tablespace_name,
SUM(b.bytes),
COUNT(b.table_name) extents,
SUM(b.blocks)
FROM
dba_tables a,
dba_extents b
WHERE
a.owner=b.owner
AND a.table_name=b.table_name
GROUP BY
a.owner, a.table_name, a.tablespace_name;
This example has the effect of altering the
stored outline get_tables to include any changes brought about by
inclusion of the SUM(b.blocks) in the SELECT list. But what if we want
to rename the outline or change a category name? The ALTER OUTLINE
command has the format:
ALTER
OUTLINE outline_name
[REBUILD]
[RENAME TO new_outline_name]
[CHANGE CATEGORY TO new_category_name]
The ALTER OUTLINE command allows us to rebuild
the outline for an existing outline_name as well as rename the outline
or change its category. The benefit of using the ALTER OUTLINE command
is that we do not have to respecify the complete SQL statement, as we
would have to using the CREATE OR REPLACE command.
Dropping an OUTLINE Object
Outlines are dropped using the DROP OUTLINE
command; the syntax for this command is:
DROP OUTLINE
outline_name;
This is an excerpt from Mike Ault, bestselling author of "Oracle
10g Grid and Real Application Clusters".
|