Question:
I wan to modify the frequency that I take my
AWR snapshots. I understand that there is a utility
that allows me to modify my AWR automatic snapshot settings.
Can you please advise me on how to modify this snapshot
settings?
Answer: The dba_hist_wr_control table shows the
AWR snapshot settings, namely the snapshot interval, the retention period and
the top-x-sql collection threshold:
SQL> desc
dba_hist_wr_control
Name
Null? Type
-------------------------------
-------- ----------------------------
DBID
NOT NULL NUMBER
SNAP_INTERVAL NOT
NULL INTERVAL DAY(5) TO SECOND(1)
RETENTION
NOT NULL INTERVAL DAY(5) TO SECOND(1)
TOPNSQL
VARCHAR2(10)
Also see my related notes on
dba_hist_wr_control.
Scheduling the AWR snapshot collection
Oracle uses the MMON background process to collect AWR statistics.
You can disable
this job by changing the
parameter STATISTICS_LEVEL to BASIC then snapshots will not be taken
automatically.
SQL> show
parameter statistics_level
NAME TYPE VALUE
------------------------------------ -----------
-------------------
statistics_level
string BASIC
You can
re-enable
this job by changing the parameter STATISTICS_LEVEL to TYPICAL then
snapshots will be taken automatically.
AWR
Snapshot Reports
Oracle provides reports that you can run to analyze the data in the AWR. There are two
reports: awrrpt.sql and
awrrpti.sql, which are available
in the directory $ORACLE_HOME/rdbms/admin.
The output of
these reports is essentially the same, except that
awrrpti.sql script allows you to
define a specific instance to report on.
The reports are
much like the statspack reports of old, in that you define a beginning and
ending snapshot ID, and the output filename of the report. Additionally, you can
opt to produce the report in either text format or HTML format.
AWR Retention Period Settings
Setting an appropriate
retention interval for your AWR is critical for proper data
retention, especially for predictive modeling. You can
adjust the AWR retention period according to your analysis
needs.
In this example the
retention period is specified as 3 years (1,576,800 minutes)
and the interval between each snapshot is 60 minutes.
execute
dbms_workload_repository.modify_snapshot_settings (
interval => 60,
retention => 1576800);
Oracle has published suggested storage
requirements for AWR based on the activity and complexity of
your 10g database:
|
Active Sessions |
number of CPU's (num_cpus) |
number of schema objects |
Monthly space required (gig) |
Small |
10 |
2 |
500 |
2 |
Medium |
20 |
8 |
5,000 |
8 |
Large |
100 |
32 |
50,000 |
20 |
Here, we choose out approximate
database size and see estimated space for the AWR dba_hist
tables. Oracle provides the SYSAUX sizing utility called
utlsyxsz.sql (in $ORACLE_HOME/rdbms/admin) for
estimating your AWR retention based on disk space
consumption.
AWR also supports the creation of "AWR
baselines", which are a "named" series of AWR snapshots that
are immune from being purged by the AWR retention mechanism.
the create_baseline procedure allows you to specify a
start_snapshot and end_snapshot and name the baseline:
DBMS_WORKLOAD_REPOSITORY.create_baseline
(1900, 2000, 'EOY_PEAK_LOADS');
The dbms_workload_repository
package can be used by Oracle DBAs to configure AWR settings
such as snapshot interval, flushing and data retention.
The dbms_workload_repository
.modify_snapshot_settings procedure is used to
configure AWR data retention in the database. The retention
interval determines the length of time that data will be
preserved in the AWR. The default setting for retention is
10,080 minutes (one week).
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 range of valid values for this
parameter ranges from ten minutes to 52,560,000 minutes or
100 years.
The dbms_workload_repository
package contains the global variables of min_retention
and max_retention. These variables set the lower
and upper limits for the retention parameter.
If a zero value is specified for
retention, snapshots will be stored for an unlimited amount
of time. The following awr_settings.sql script can be used
to check the current settings for the AWR interval and
retention settings:
awr_settings.sql
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;
The script returns the current AWR
interval values in minutes:
Snapshot Interval Retention Interval
----------------- ------------------
60 10080
Top-n SQL thresholds
The topnsql is used to specify the number of SQL to
collect at each AWR snapshot for each criteria like elapsed
time, CPU time, parse calls, shareable memory, and version
count. The topnsql is normally set to a small
number like 10, because you only want to see the most
current SQL statements. This SQL information is normally
purged after a period of time, after which the SQL source
code is no longer needed.
begin
dbms_workload_repository.modify_snapshot_settings(
retention => 7200,
interval =>60 ,
topnsql =>10 ,
dbid => 123661118);
end;
/
There are 14 criteria in an AWR report, and Oracle AWR will
capture the top-n-SQL for each of these criteria:
1. Elapsed Time (ms)
2. CPU Time (ms)
3. Executions
4. Buffer Gets
5. Disk Reads
6. Parse
Calls
7. Rows
8. User I/O Wait Time (ms)
9 Cluster
Wait Time (ms)
10. Application Wait Time (ms)
11.
Concurrency Wait Time (ms)
12. Invalidations
13.
Version Count
14. Sharable Mem(KB)
You can also set threshold for each of the criteria.
Unlike STATSPACK, AWR uses a "Top N" method
which defaults to collect the Top-30 SQL statements for each
SQL category, If you set statistics_level = "all", AWR will
collect the top 100 SQL statements.
The number of SQL statements captured also depends on your
statistics_level setting:
- When
statistics_level=typical, AWR will capture the topnsql.
Without the topnsql set, the default is to capture 30 SQL
statements, for a total of 420 per snapshot.
- When
statistics_level=all, AWR will capture the top 100
SQL for each of the criteria (elapsed time, CPU, disk reads,
etc.), for a total of 1400 SQL statements per snapshot.
Of course, some SQL statements will appear in more then one
category.
|
|
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.
|