maclean
2010-08-20
<strong>FAQ – Automatic Undo Management (AUM) / System Managed Undo (SMU) </strong>
Applies to:
Oracle Server - Enterprise Edition - Version: 9.0.1.4 to 11.1.0.6
Information in this document applies to any platform.
Oracle RDBMS Server
<a></a>Purpose
This article is intended for Database Administrators with knowledge on Automatic Undo Management (AUM).
And we have covered major questions related to Automatic Undo Management (AUM) which will be helpful during creation (or) monitoring the undo tablespaces.
<a></a>Questions and Answers
<a></a>What is Undo?
Oracle maintains information to nullify changes made to the database. Such information consists of records of the actions of transactions, collectively known as undo. Oracle uses the undo to do the following:
- Rollback an active transaction
- Recover a terminated transaction
- Provide read consistency
- Recovery from logical corruptions
What is AUM / SMU?
Automatic Undo Management(AUM) is introduced in Oracle 9i, which replaces the rollback segments.
This is also called System Managed Undo(SMU) as the undo is managed by oracle.
Automatic undo management is undo-tablespace based. You allocate space in the form of an undo tablespace, instead of allocating many rollback segments in different sizes.
Oracle strongly recommends their customers to use Automatic Undo Management (AUM).
<a></a>Which are the major initialization parameters that controls AUM?
UNDO_MANAGEMENT Initialization Parameter
UNDO_MANAGEMENT specifies which undo space management mode the system should use. When set to AUTO, the instance starts in automatic undo management mode. In manual undo management mode, undo space is allocated externally as rollback segments.
By default, this parameter is set to MANUAL. Set this parameter to AUTO to enable automatic undo management mode.
This is a static parameter and cannot be modified dynamically using alter system command.
So if you wish to switch between Rollback Segments and AUM, then you need to restart the instance.
In RAC, multiple instances must have the same value.
UNDO_TABLESPACE Initialization Parameter
When an instance starts up in automatic undo management mode, it attempts to select an undo tablespace for storage of undo data.
UNDO_RETENTION Initialization Parameter
This parameter specifies (in seconds) the low threshold value of undo retention.
The UNDO_RETENTION parameter can only be honored if the current undo tablespace has enough space. If an active transaction requires undo space and the undo tablespace does not have available space, then the system starts reusing unexpired undo space. This action can potentially cause some queries to fail with a "snapshot too old" message.
The amount of time for which undo is retained for the Oracle Database for the current undo tablespace can be obtained by querying the TUNED_UNDORETENTION column of the V$UNDOSTAT dynamic performance view.
<a></a>How many Undo tablespaces can we have for a database?
We can have many undo tablespaces in a database, but only one can be Active per instance.
In Oracle Real Application Clusters (RAC) enviornment, we need to have one Active undo tablespace per instance. The UNDO_TABLESPACE parameter will be used for assigning a particular undo tablespace to an instance.
<a></a>
How to switch to a new undo tablespace?
You can switch from using one undo tablespace to another. Because the UNDO_TABLESPACE initialization parameter is a dynamic parameter, the ALTER SYSTEM SET statement can be used to assign a new undo tablespace.
The following statement switches to a new undo tablespace:
ALTER SYSTEM SET UNDO_TABLESPACE = undotbs_02;
Assuming undotbs_01 is the current undo tablespace, after this command successfully executes, the instance uses undotbs_02 in place of undotbs_01 as its undo tablespace.
If any of the following conditions exist for the tablespace being switched to, an error is reported and no switching occurs:
The tablespace does not exist
The tablespace is not an undo tablespace
The tablespace is already being used by another instance (in a RAC environment only)
The database is online while the switch operation is performed, and user transactions can be executed while this command is being executed. When the switch operation completes successfully, all transactions started after the switch operation began are assigned to transaction tables in the new undo tablespace.
The switch operation does not wait for transactions in the old undo tablespace to commit. If there are any pending transactions in the old undo tablespace, the old undo tablespace enters into a PENDING OFFLINE mode (status). In this mode, existing transactions can continue to execute, but undo records for new user transactions cannot be stored in this undo tablespace.
An undo tablespace can exist in this PENDING OFFLINE mode, even after the switch operation completes successfully. A PENDING OFFLINE undo tablespace cannot be used by another instance, nor can it be dropped. Eventually, after all active transactions have committed, the undo tablespace automatically goes from the PENDING OFFLINE mode to the OFFLINE mode. From then on, the undo tablespace is available for other instances (in an Oracle Real Application Cluster environment).
If the parameter value for UNDO TABLESPACE is set to '' (two single quotes), then the current undo tablespace is switched out and the next available undo tablespace is switched in. Use this statement with care because there may be no undo tablespace available.
The following example unassigns the current undo tablespace:
ALTER SYSTEM SET UNDO_TABLESPACE = '';
NOTE: There is not a way to shrink an existing UNDO tablespace. You can change UNDO tablespaces instead. See <a href="https://support.oracle.com/CSP/main/article?cmd=show&type=NOT&id=268870.1" rel="nofollow">Note 268870.1</a> How to Shrink the datafile of Undo Tablespace
<a></a>What is UNDO Retention?
Undo Retention refers to duration of retaining the undo data after a transaction.
After a transaction is committed, undo data is no longer needed for rollback or transaction recovery purposes. However, for consistent read purposes, long-running queries may require this old undo information for producing older images of data blocks. Furthermore, the success of several Oracle Flashback features can also depend upon the availability of older undo information. For these reasons, it is desirable to retain the old undo information for as long as possible.
Automatic undo management eliminates the complexities of managing rollback segment space and lets you exert control over how long undo is retained before being overwritten.
You can set the UNDO_RETENTION parameter to a low threshold value so that the system retains the undo for at least the time specified in the parameter.
<a></a>What is Automatic UNDO Retention (10g New Feature)? Explain.
There is no parameter for this, Automatic UNDO Retention is enabled by default in 10g.
Oracle Database 10g automatically tunes a parameter called the undo retention period. The undo retention period indicates the amount of time that must pass before old undo information. Which means the undo information for committed transactions can be overwritten. The database collects usage statistics and tunes the undo retention period based on these statistics and on undo tablespace size. Provided that automatic undo management is enabled, the database automatically tunes the undo retention period as follows:
The current value for tuned undo retention can be viewed by following query.
SELECT TO_CHAR(BEGIN_TIME, 'MM/DD/YYYY HH24:MI:SS') BEGIN_TIME,
TUNED_UNDORETENTION FROM V$UNDOSTAT;
For AUTOEXTEND undo tablespaces, the system retains undo for at least the time specified in this parameter, and automatically tunes the undo retention period to satisfy the undo requirements of the queries.
This could lead to excessive undo generation, to honor undo retention
For fixed- size undo tablespaces, the system automatically tunes for the maximum possible undo retention period, based on undo tablespace size and usage history, and ignores UNDO_RETENTION unless retention guarantee is enabled.
Automatic tuning of undo retention is not supported for LOBs. Because we don't store any undo information in undo tablespace for transactions on LOBs.
<a></a>What is Guaranteed UNDO Retention? Explain.
Oracle Database 10g lets you guarantee undo retention. In Oracle 10g Release 2, you can enable and disable undo retention.
When you enable this option, the database never overwrites unexpired undo data. That is undo data whose age is less than the undo retention period.
This option is disabled by default, which means that the database can overwrite the unexpired undo data to avoid failure of DML operations if there is not enough free space left in the undo tablespace.
By enabling the guarantee option, you instruct the database not to overwrite unexpired undo data even if it means risking failure of currently active DML operations. Therefore, use caution when enabling this feature.
To enable do the following against the undo tablespace.
ALTER TABLESPACE UNDOTBS RETENTION GUARANTEE;
A typical use of the guarantee option is when you want to ensure deterministic and predictable behavior of Flashback Query by guaranteeing the availability of the required undo data.
<a></a>Explain V$UNDOSTAT, and usage?
This view is a replacement / enhancement for V$ROLLSTAT.
This view contains statistics for monitoring and tuning undo space. Use this view to help estimate the amount of undo space required for the current workload. The database also uses this information to help tune undo usage in the system. This view is meaningful only in automatic undo management mode.
The V$UNDOSTAT view is useful for monitoring the effects of transaction execution on undo space in the current instance. Statistics are available for undo space consumption, transaction concurrency, the tuning of undo retention, and the length and SQL ID of long-running queries in the instance.
Each row in the view contains statistics collected in the instance for a ten-minute interval. The rows are in descending order by the BEGIN_TIME column value. Each row belongs to the time interval marked by (BEGIN_TIME, END_TIME). Each column represents the data collected for the particular statistic in that time interval.
SELECT TO_CHAR(BEGIN_TIME, 'MM/DD/YYYY HH24:MI:SS') BEGIN_TIME,
TO_CHAR(END_TIME, 'MM/DD/YYYY HH24:MI:SS') END_TIME,
UNDOTSN, UNDOBLKS, TXNCOUNT, MAXCONCURRENCY AS "MAXCON",
MAXQUERYLEN, TUNED_UNDORETENTION
FROM v$UNDOSTAT;
The following table explains other useful columns of V$UNDOSTAT view
UNXPSTEALCNT
The number of attempts when unexpired blocks were stolen from other undo segments to satisfy space requests
UNXPBLKRELCNT
The number of unexpired blocks removed from undo segments to be used by other transactions
UNXPBLKREUCNT
The number of unexpired undo blocks reused by transactions
EXPSTEALCNT
The number of attempts when expired extents were stolen from other undo segments to satisfy a space requests
EXPBLKRELCNT
The number of expired extents stolen from other undo segments to satisfy a space request
EXPBLKREUCNT
The number of expired undo blocks reused within the same undo segments
SSOLDERRCNT
The number of ORA-1555 errors that occurred during the interval
NOSPACEERRCNT
The number of Out-of-Space errors
When the columns UNXPSTEALCNT through EXPBLKREUCNT hold non-zero values, it is an indication of space pressure.
If the column SSOLDERRCNT is non-zero, then UNDO_RETENTION is not properly set.
If the column NOSPACEERRCNT is non-zero, then there is a serious space problem.
In 10g DBA_HIST_UNDOSTAT view contains statistical snapshots of V$UNDOSTAT information.
<a></a>Explain the DBA_UNDO_EXTENTS View, and usage?
DBA_UNDO_EXTENTS describes the extents comprising the segments in all undo tablespaces in the database. This view shows the status and size of each extent in the undo tablespace.
<a></a>What are the various statuses for Undo Extents? Explain.
Transaction Status of the undo in the extent can be any of the following:
SELECT DISTINCT STATUS, SUM(BYTES), COUNT(*)
FROM DBA_UNDO_EXTENTS GROUP BY STATUS;
ACTIVE - Undo Extent is Active, Used by a transaction.
EXPIRED - Undo Extent is expired (Exceeded the Undo Retention).
UNEXPIRED - Undo Extent will be required to honor UNDO_RETENTION.
<a></a>
Explain V$TRANSACTION, and usage?
V$TRANSACTION lists the active transactions in the system.
(a) The following columns together points to a transaction. (ie) The combination of the following should give unique transaction id for that database.
XIDUSN - Undo segment number
XIDSLOT - NUMBER Slot number
XIDSQN - NUMBER Sequence number
(b) The following columns explains the number of undo blocks / undo records used per transaction.
USED_UBLK - Number of undo blocks used
USED_UREC - Number of undo records used
In the case of transaction rollback, the above columns will give estimation about the number of undo blocks that needs to be rolled back.
The number of undo records and undo blocks (USED_UREC and USED_UBLK) decrease while the transaction is rolling back. When they reach 0, the transaction disappears from v$transaction.
The following query can be used to monitor the transaction rollback.
SELECT A.SID, A.USERNAME, B.XIDUSN, B.USED_UREC, B.USED_UBLK
FROM V$SESSION A, V$TRANSACTION B
WHERE A.SADDR=B.SES_ADDR;
(c) The STATUS following column explains the status of a transaction.
ACTIVE - Explains the transaction is active.
Before performing a normal/transactional shutdown, we can check this view to understand if we have any ACTIVE transactions.
SELECT XIDUSN, XIDSLT, XIDSEQ , SES_ADDR, STATUS FROM V$TRANSACTION;
<a></a>Explain DBA_ROLLBACK_SEGS, and usage?
This view explains the various status of Undo Segments.
In RAC, we can also see the Instance number, and its associated tablespaces.
SELECT INSTANCE_NUM,TABLESPACE_NAME,SEGMENT_NAME,STATUS FROM DBA_ROLLBACK_SEGS;
In AUM DBA's don't have privileges to offline/online undo segments. And this is controlled by SMON process. So this will be useful only in few scenarios, where we have internal errors with undo segments.
<a></a>Do we have scripts to monitor the undo growth/usage of the database?
To understand the free space with undo tablespace.
SELECT SUM(BYTES) FROM DBA_FREE_SPACE WHERE TABLESPACE_NAME='&UNDOTBS';
To understand state of the extents, space-used in the current undo tablespace.
SELECT DISTINCT STATUS, SUM(BYTES), COUNT(*)
FROM DBA_UNDO_EXTENTS GROUP BY STATUS;
To understand the no of active transactions and its undo usage.
SELECT XIDUSN, XIDSLOT, XIDSQN, USED_UBLK FROM V$TRANSACTION WHERE STATUS='ACTIVE' ;
<a></a>
What are the possible causes for excessive undo growth?
There could be various causes for excessive undo growth. To start the diagnosis we need to understand the following.
<strong>Transactions with huge undo
</strong>It is obvious to see high undo usage when there are huge transactions.
If that is going to be the case this growth should be expected behavior.
<strong>UNDO RETENTION</strong>
Higher undo retention will cause higher undo growth. Because we wont mark the undo extents as EXPIRED till the duration of undo retention.
Disabling autoextend on datafiles of active undo tablespace will reuse the UNEXPIRED extents when it has space crunch. It is a trade-off between undo retention and undo space.
If you wish to satisfy Undo Retention, switch on autoextend in undo tablespace datafiles.
SELECT FILE_ID, AUTOEXTENSIBLE FROM DBA_DATA_FILES WHERE
TABLESPACE_NAME='&UNDOTBS';
To make those datafile auto extensible, run the following command.
ALTER DATABASE DATAFILE '&FILE_ID' AUTOEXTEND ON;
If you wish to switch off auto extend and to reuse the UNEXPIRED space, do the following
ALTER DATABASE DATAFILE '&FILE_ID' AUTOEXTEND OFF;
<strong>State of undo extents
</strong>The status of the undo extents needs to be closely monitored.
There are few bugs with different releases where EXPIRED extents are not being reused.
(a) If good number of extents in UNEXPIRED status, it could be due to high undo_retention.
SELECT DISTINCT STATUS, SUM(BYTES), COUNT(*)
FROM DBA_UNDO_EXTENTS GROUP BY STATUS;
(b) There are few bugs associated with undo usage,
The unpublished bug 5442919 affects 10.2.0.3, 10.1.0.5 , 9.2.0.8 and its lesser patch levels, and the issue is fixed in 10.2.0.4.
Bug 5442919 EXPIRED EXTENTS NOT BEING REUSED
The above bug is unpublished, and the details can be reviewed through <a href="https://support.oracle.com/CSP/main/article?cmd=show&type=NOT&id=5442919.8" rel="nofollow">Note:5442919.8</a>
And we also have <a href="https://updates.oracle.com/ARULink/PatchDetails/process_form?patch_num=5442919" rel="nofollow">Patch:5442919</a> for most of the latest versions. Kindly check metalink for patch availability.
<a></a>How to resize the undo datafile?
It is possible to increase an undo datafile. For example, to increase the undo datafile size from 2000 MB to 3000MB we can do the following
ALTER DATABASE DATAFILE 39 RESIZE 3000M;
But it may not be possible to resize to lesser value, when a undo datafile got auto extended to higher value. Even after the transactions are completed those undo extents will remain in EXPIRED status.
As the blocks are being used by undo extents, oracle will not allow you to resize, It will result in errors similar to following. In the following case the datafile size was 3500MB and a resize to 3000MB results in following errors.
SQL> alter database datafile 39 resize 3000m;
alter database datafile 39 resize 3000m
*
ERROR at line 1:
ORA-03297: file contains used data beyond requested RESIZE value