Call now: 252-767-6166  
Oracle Training Oracle Support Development Oracle Apps

 
 Home
 E-mail Us
 Oracle Articles
New Oracle Articles


 Oracle Training
 Oracle Tips

 Oracle Forum
 Class Catalog


 Remote DBA
 Oracle Tuning
 Emergency 911
 RAC Support
 Apps Support
 Analysis
 Design
 Implementation
 Oracle Support


 SQL Tuning
 Security

 Oracle UNIX
 Oracle Linux
 Monitoring
 Remote s
upport
 Remote plans
 Remote
services
 Application Server

 Applications
 Oracle Forms
 Oracle Portal
 App Upgrades
 SQL Server
 Oracle Concepts
 Software Support

 Remote S
upport  
 Development  

 Implementation


 Consulting Staff
 Consulting Prices
 Help Wanted!

 


 Oracle Posters
 Oracle Books

 Oracle Scripts
 Ion
 Excel-DB  

Don Burleson Blog 


 

 

 


 

 

 
 

Disabling AWR data purging

Oracle Database Tips by Donald BurlesonMarch 25, 2013

Question:  I want to keep my AWR data long-term and disable the jobs that periodically purge the AWR snapshots.  What are the best practices for keeping AWR data for many months and years?

Answer:  There are several ways to keep long-term AWR performance data.  Keeping AWR data long-term involves these steps:

1 - Truncate the SQL tables periodically

2 - Modify the snapshot retention period

3 - Remove the automatic flush job

Also see my notes on  how to remove AWR.

One question is whether or not to compress the AWR data by removing the SQL table data periodically. 

Compressing AWR data

If you choose to compress the AWR data, you will need to periodically truncate these "unnecessary" tables.  These tables contain SQL that is rarely useful after a month.  Note:  You must be connected as SYSDBA to truncate these tables.

  • wrh$_sqlstat contains a history for SQL execution statistics and stores snapshots of v$sql view.

  • wrh$_sqltext stores actual text for SQL statements captured from v$sql.

  • wrh$_sql_plan stores execution plans for SQL statements available in dba_hist_sqlstat.

connect sys/manager as sysdba;

truncate table wrh$_sqlstat;
truncate table wrh$_sqltext;
truncate table wrh$_sql_plan;

You can schedule this periodic truncate of the SQL tables using either dbms_scheduler or with a crontab job.

 

Change retention period for snapshots:

The AWR has a special background process, MMON, which is responsible for gathering regular snapshots. The DBA is able to specify the frequency at which MMON gathers snapshots via the dbms_workload_repository .modify_snapshot_settings procedure:

 

SQL> desc dbms_workload_repository

PROCEDURE MODIFY_SNAPSHOT_SETTINGS

Argument Name Type In/Out Default?

----------------- --------------- ------ --------

RETENTION NUMBER IN DEFAULT

INTERVAL NUMBER IN DEFAULT

DBID NUMBER IN DEFAULT

The interval parameter sets the time interval, in minutes, between the snapshots. The default interval between snapshots is 60 minutes. The valid range of values for this parameter ranges from 10 minutes to 52,560,000 minutes (100 years).

 

The dbms_workload_repository package has the global variables min_interval and max_interval , which set the lower and upper limits for this parameter. If the value specified for the interval is zero, automatic and manual snapshots will be prohibited.

The first dbms_workload_repository.modify_snapshot_settings procedure parameter, retention , allows the DBA to specify the time period, in minutes. The AWR will preserve that particular snapshot in the repository. The default value for this parameter is 10,080 minutes (seven days).

 

The valid range of values for this parameter also ranges from 10 minutes to 52,560,000 minutes (100 years). The dbms_workload_repository package has global variables min_retention and max_retention, which set up the lower and upper limits for the retention parameter.

 

NOTE:  If a zero value is specified for retention, snapshots will be stored for an unlimited time.

The current settings for AWR retention and interval parameters can be viewed using dba_hist_wr_control data dictionary view.

 

select
   extract( day from snap_interval) *24*60+
   extract( hour from snap_interval) *60+
   extract( minute from snap_interval ) "Snapshot Interval",
   extract( day from retention) *24*60+
   extract( hour from retention) *60+
   extract( minute from retention ) "Retention Interval"
from
   dba_hist_wr_control;

 This script returns the current AWR interval values in minutes:

Snapshot Interval Retention Interval

----------------- ------------------

60                10080

Here are examples of modifying the snapshot collection thresholds

dbms_workload_repository.modify_snapshot_settings(retention = > 0)

AWR flushing and the MMON background process

The MMON Oracle background process is responsible for periodically flushing the oldest AWR tables, using a LIFO queue method. Here, we see the flush_level for an AWR installation:

SQL> desc dbms_workload_repository

PROCEDURE CREATE_SNAPSHOT
Argument Name Type In/Out Default?
------------------------------ ----------------------- ------ --------
FLUSH_LEVEL VARCHAR2 IN DEFAULT

FUNCTION CREATE_SNAPSHOT RETURNS NUMBER
Argument Name Type In/Out Default?
------------------------------ ----------------------- ------ --------
FLUSH_LEVEL VARCHAR2 IN DEFAULT

The only parameter listed in the procedures is the flush_level , which can have either the default value of TYPICAL or a value of ALL. When the statistics level is set to ALL, the AWR gathers the maximum amount of performance data.

The MMON background process is responsible for removing old historical data from the AWR. The amount of retention time after which data will be removed from database is determined by the retention setting.

However, data can be cleared from the AWR tables by using the dbms_workload_repository.drop_snapshot_range procedure. The starting and ending snapshots for the history to be removed from the AWR will need to be set to run the following script, drop_snapshot_range.

desc dbms_workload_repository

PROCEDURE DROP_SNAPSHOT_RANGE
Argument Name Type In/Out Default?
------------------------------ -------------------- ------ --------
LOW_SNAP_ID NUMBER IN
HIGH_SNAP_ID NUMBER IN
DBID NUMBER IN DEFAULT


Disabling and enabling automatic AWR flushing

You can disable the AWR automatic data flushing mechanism at either the system level or disable flushing for individual tables.

For system-wide disable of AWR table flushing you can use these commands but beware that the AWR tablespace will continue to grow ad-infinitum:

alter session set events 'immediate trace name awr_flush_table_off level 99′
alter session set events 'immediate trace name awr_flush_table_off level 106′;

To return to the default of weekly flushing you can issue these commands:

alter session set events 'immediate trace name awr_flush_table_on level 99′;
alter session set events 'immediate trace name awr_flush_table_on level 106′;

If you need to disable flushing the run time statistics for an AWR workload table, you can get the underlying WRH tables with this query:

select
   table_id_kewrtb,
   table_name_kewrtb
from
   x$kewrtb
order by
   table_id_kewrtb;

Once you identify specific AWR tables to disable flushing, you can use an ALTER SYSTEM command:

alter system set "_awr_disabled_flush_tables"=WRH$_FILESTATXS_BL;
alter system set "_awr_disabled_flush_tables"=WRH$_TEMPSTATXS;
alter system set "_awr_disabled_flush_tables"=WRH$_DATAFILE;
alter system set "_awr_disabled_flush_tables"=WRH$_TEMPFILE;
alter system set "_awr_disabled_flush_tables"=WRH$_COMP_IOSTAT;
alter system set "_awr_disabled_flush_tables"=WRH$_SQLSTAT_BL;

You can run a script like this to mark all of the important AWR tables:

WARNING:  SETTING UNDOCUMENTED PARAMETERS REQUIRE NOTIFYING MOSC.

set pages 9999;

spool runme.sql

select
'alter system set "_awr_disabled_flush_tables"='||table_name||';'
from
   dba_tables
where
   tablespace_name = 'SYSAUX'
and
   table_name like 'WRH_%';

spool off
runme.sql


 

References from MOSC:

- General Guidelines for SYSAUX Space Issues [Document 552880.1]

- SYSAUX Tablespace Grows Heavily Due To AWR [Document 852028.1]

- SYSAUX Grows Because Optimizer Stats History is Not Purged [Document 1055547.1]

- Space issue in Sysaux tablespace due to Unexpected AWR size [Document 1218413.1]

- Space Management In Sysaux Tablespace with AWR in Use [Document 287679.1]

- Usage and Storage Management of SYSAUX tablespace occupants SM/AWR, SM/ADVISOR, SM/OPTSTAT and SM/OTHER [Document 329984.1]

 

 
Get the Complete
Oracle SQL Tuning Information 

The landmark book "Advanced Oracle SQL Tuning  The Definitive Reference"  is filled with valuable information on Oracle SQL Tuning. This book includes scripts and tools to hypercharge Oracle 11g performance and you can buy it for 30% off directly from the publisher.

 

 

Burleson is the American Team

Note: This Oracle documentation was created as a support and Oracle training reference for use by our DBA performance tuning consulting professionals.  Feel free to ask questions on our Oracle forum.

Verify experience! Anyone considering using the services of an Oracle support expert should independently investigate their credentials and experience, and not rely on advertisements and self-proclaimed expertise. All legitimate Oracle experts publish their Oracle qualifications.

Errata?  Oracle technology is changing and we strive to update our BC Oracle support information.  If you find an error or have a suggestion for improving our content, we would appreciate your feedback.  Just  e-mail:  

and include the URL for the page.


                    









Burleson Consulting

The Oracle of Database Support

Oracle Performance Tuning

Remote DBA Services


 

Copyright © 1996 -  2017

All rights reserved by Burleson

Oracle ® is the registered trademark of Oracle Corporation.

Remote Emergency Support provided by Conversational

 

 

��  
 
 
Oracle Training at Sea
 
 
 
 
oracle dba poster
 

 
Follow us on Twitter 
 
Oracle performance tuning software 
 
Oracle Linux poster