Oracle® Database Administrator's Guide 11g Release 2 (11.2) Part Number E10595-04 |
|
|
View PDF |
Automatic tuning of undo retention typically achieves better results with a fixed-size undo tablespace. If you decide to use a fixed-size undo tablespace, the Undo Advisor can help you estimate needed capacity. You can access the Undo Advisor through Enterprise Manager or through the DBMS_ADVISOR
PL/SQL package. Enterprise Manager is the preferred method of accessing the advisor. For more information on using the Undo Advisor through Enterprise Manager, see Oracle Database 2 Day DBA.
The Undo Advisor relies for its analysis on data collected in the Automatic Workload Repository (AWR). It is therefore important that the AWR have adequate workload statistics available so that the Undo Advisor can make accurate recommendations. For newly created databases, adequate statistics may not be available immediately. In such cases, continue to use the default auto-extending undo tablespace until at least one workload cycle completes.
An adjustment to the collection interval and retention period for AWR statistics can affect the precision and the type of recommendations that the advisor produces. See Oracle Database Performance Tuning Guide for more information.
To use the Undo Advisor, you first estimate these two values:
The length of your expected longest running query
After the database has completed a workload cycle, you can view the Longest Running Query field on the System Activity subpage of the Automatic Undo Management page.
The longest interval that you will require for Oracle Flashback operations
For example, if you expect to run Oracle Flashback queries for up to 48 hours in the past, your Oracle Flashback requirement is 48 hours.
You then take the maximum of these two values and use that value as input to the Undo Advisor.
Running the Undo Advisor does not alter the size of the undo tablespace. The advisor just returns a recommendation. You must use ALTER
DATABASE
statements to change the tablespace datafiles to fixed sizes.
The following example assumes that the undo tablespace has one auto-extending datafile named undotbs.dbf
. The example changes the tablespace to a fixed size of 300MB.
ALTER DATABASE DATAFILE '/oracle/dbs/undotbs.dbf' RESIZE 300M; ALTER DATABASE DATAFILE '/oracle/dbs/undotbs.dbf' AUTOEXTEND OFF;
Note:
If you want to make the undo tablespace fixed-size, Oracle suggests that you first allow enough time after database creation to run a full workload, thus allowing the undo tablespace to grow to its minimum required size to handle the workload. Then, you can use the Undo Advisor to determine, if desired, how much larger to set the size of the undo tablespace to allow for long-running queries and Oracle Flashback operations.See Also:
Oracle Database 2 Day DBA for instructions for computing the minimum undo tablespace size with the Undo AdvisorYou can activate the Undo Advisor by creating an undo advisor task through the advisor framework. The following example creates an undo advisor task to evaluate the undo tablespace. The name of the advisor is 'Undo Advisor'. The analysis is based on Automatic Workload Repository snapshots, which you must specify by setting parameters START_SNAPSHOT
and END_SNAPSHOT
. In the following example, the START_SNAPSHOT
is "1" and END_SNAPSHOT
is "2".
DECLARE tid NUMBER; tname VARCHAR2(30); oid NUMBER; BEGIN DBMS_ADVISOR.CREATE_TASK('Undo Advisor', tid, tname, 'Undo Advisor Task'); DBMS_ADVISOR.CREATE_OBJECT(tname, 'UNDO_TBS', null, null, null, 'null', oid); DBMS_ADVISOR.SET_TASK_PARAMETER(tname, 'TARGET_OBJECTS', oid); DBMS_ADVISOR.SET_TASK_PARAMETER(tname, 'START_SNAPSHOT', 1); DBMS_ADVISOR.SET_TASK_PARAMETER(tname, 'END_SNAPSHOT', 2); DBMS_ADVISOR.SET_TASK_PARAMETER(tname, 'INSTANCE', 1); DBMS_ADVISOR.execute_task(tname); END; /
After you have created the advisor task, you can view the output and recommendations in the Automatic Database Diagnostic Monitor in Enterprise Manager. This information is also available in the DBA_ADVISOR_*
data dictionary views (DBA_ADVISOR_TASKS
, DBA_ADVISOR_OBJECTS
, DBA_ADVISOR_FINDINGS
, DBA_ADVISOR_RECOMMENDATIONS
, and so on).
See Also:
"Using the Segment Advisor" for an example of creating an advisor task for a different advisor
Oracle Database Reference for information about the DBA_ADVISOR_*
data dictionary views