Total Pageviews

Monday, 1 June 2015

SYSAUX consuming more space

SYSAUX consuming more space
========================

Tips regarding 
SYSAUX Space Usage:
================
  • Make sure the SYSAUX tablespace is set to AUTOEXTEND off     -- This allows storage to be re-used vs. appended to
  • Confirm the STATISTICS_LEVEL value **                                    --  ALL is known to potentially be resource intensive while Basic and Typical are typically not
  • Check for the usage of advisors, baselines or sql tuning sets:   -- These require trapping information which is retained in snapshots even if the snapshot range was scheduled to be dropped
  • Run awrinfo.sql scripts on each instance                                    -- To better report and verify which objects are consuming the most space in the SYSAUX tablespace.
  • Run queries against sysaux_occupants                                      -- A simple method to get general information on SYSAUX storage consumption


A nicely formated report can be generated by running the awrinfo.sql script
SQL> connect / as sysdba
SQL> @?/rdbms/admin/awrinfo.sql                   --- For Windows - The script ( = @ ) was executed from the Oracle_Home (= ? ) if set

In the report you may tend to see the following or similar tables are consuming the most storage space

1. WRH$_ACTIVE_SESSION_HISTORY     
2. WRI$_OPTSTAT_HISTGRM_HISTORY
3. WRI$_OPTSTAT_HISTHEAD_HISTORY
@?/rdbms/admin/awrinfo.sql

In my case the culprit was

Space usage by non-AWR components (> 500K)
**********************************

COMPONENT MB SEGMENT_NAME SEGMENT_TYPE
--------- --------- --------------------------------------------------------------------- ---------------
NON_AWR 743.0 SYS.I_WRI$_OPTSTAT_HH_OBJ_ICOL_ST INDEX
NON_AWR 512.0 SYS.I_WRI$_OPTSTAT_HH_ST INDEX
NON_AWR 375.0 SYS.WRI$_OPTSTAT_OPR TABLE
NON_AWR 155.0 SYS.WRI$_OPTSTAT_OPR_TASKS TABLE
NON_AWR 144.0 SYS.WRI$_OPTSTAT_HISTHEAD_HISTORY.SYS_P11840 TABLE PARTITION

| Occupant Name Schema Name Space Usage
| -------------------- -------------------- ----------------
| SM/OPTSTAT SYS 3,260.1 MB


Resolution
======
exec DBMS_STATS.PURGE_STATS(DBMS_STATS.PURGE_ALL);
this will truncate all stats history tables .


changed the value to 4 days as it will purge every 31 days

exec dbms_stats.alter_stats_history_retention(4);

You can query DBA_AUTOTASK_CLIENT_HISTORY
DBA_AUTOTASK_CLIENT_HISTORY displays a per-window history of job execution counts for each automated maintenance task. In the history, you can see if the job has run successfully in the past and when it stopped running succesfully.


SQL> SELECT client_name, window_name, jobs_created, jobs_started, jobs_completed, window_start_time,window_end_time FROM dba_autotask_client_history WHERE client_name like '%stats%'; 


How long old stats are kept

select dbms_stats.get_stats_history_retention from dual;
Set retention of old stats to 10 days

exec dbms_stats.alter_stats_history_retention(10);
Purge stats older than 10 days (best to do this in stages if there is a lot of data (sysdate-30,sydate-25 etc)

exec DBMS_STATS.PURGE_STATS(SYSDATE-10);
Show available stats that have not been purged

select dbms_stats.get_stats_history_availability from dual;
Show how big the tables are and rebuild after stats have been purged

col Mb form 9,999,999
col SEGMENT_NAME form a40
col SEGMENT_TYPE form a6
set lines 120
select sum(bytes/1024/1024) Mb, segment_name,segment_type from dba_segments
where  tablespace_name = 'SYSAUX'
and segment_name like 'WRI$_OPTSTAT%'
and segment_type='TABLE'
group by segment_name,segment_type order by 1 asc
        MB SEGMENT_NAME                             SEGMEN
---------- ---------------------------------------- ------
         0 WRI$_OPTSTAT_OPR                         TABLE
         0 WRI$_OPTSTAT_AUX_HISTORY                 TABLE
        88 WRI$_OPTSTAT_TAB_HISTORY                 TABLE
       126 WRI$_OPTSTAT_IND_HISTORY                 TABLE
       158 WRI$_OPTSTAT_HISTGRM_HISTORY             TABLE
     4,482 WRI$_OPTSTAT_HISTHEAD_HISTORY            TABLE
Show how big the indexes are ready for a rebuild after stats have been purged

col Mb form 9,999,999
col SEGMENT_NAME form a40
col SEGMENT_TYPE form a6
set lines 120
select sum(bytes/1024/1024) Mb, segment_name,segment_type from dba_segments
where  tablespace_name = 'SYSAUX'
and segment_name like '%OPT%'
and segment_type='INDEX'
group by segment_name,segment_type order by 1 asc
/
        MB SEGMENT_NAME                             SEGMEN
---------- ---------------------------------------- ------
         0 WRH$_OPTIMIZER_ENV_PK                    INDEX
         0 I_WRI$_OPTSTAT_OPR_STIME                 INDEX
         0 I_WRI$_OPTSTAT_AUX_ST                    INDEX
        88 I_WRI$_OPTSTAT_TAB_ST                    INDEX
       105 I_WRI$_OPTSTAT_IND_ST                    INDEX
       105 I_WRI$_OPTSTAT_H_ST                      INDEX
       195 I_WRI$_OPTSTAT_TAB_OBJ#_ST               INDEX
       213 I_WRI$_OPTSTAT_H_OBJ#_ICOL#_ST           INDEX
       214 I_WRI$_OPTSTAT_IND_OBJ#_ST               INDEX
     2,055 I_WRI$_OPTSTAT_HH_ST                     INDEX
     3,883 I_WRI$_OPTSTAT_HH_OBJ_ICOL_ST            INDEX
Note that you cannot enable row movement and shrink the tables as the indexes are function based

alter table WRI$_OPTSTAT_IND_HISTORY enable row movement;
alter table WRI$_OPTSTAT_IND_HISTORY shrink space;
*
ERROR at line 1:
ORA-10631: SHRINK clause should not be specified for this object

select 'alter table '||segment_name||'  move tablespace SYSAUX;' from dba_segments where tablespace_name = 'SYSAUX'
and segment_name like '%OPT%' and segment_type='TABLE'
Run the rebuild table commands – note that this does cause any gather_stats jobs to fail

alter table WRI$_OPTSTAT_TAB_HISTORY  move tablespace sysaux;
alter table WRI$_OPTSTAT_IND_HISTORY  move tablespace sysaux;
alter table WRI$_OPTSTAT_HISTHEAD_HISTORY  move tablespace sysaux;
alter table WRI$_OPTSTAT_HISTGRM_HISTORY  move tablespace sysaux;
alter table WRI$_OPTSTAT_AUX_HISTORY  move tablespace sysaux;
alter table WRI$_OPTSTAT_OPR  move tablespace sysaux;
alter table WRH$_OPTIMIZER_ENV  move tablespace sysaux;
Script to generate rebuild statements

select 'alter index '||segment_name||'  rebuild online parallel (degree 14);' from dba_segments where tablespace_name = 'SYSAUX'
and segment_name like '%OPT%' and segment_type='INDEX'
Once completed it is best to check that the indexes (indices) are usable

select  di.index_name,di.index_type,di.status  from  dba_indexes di , dba_tables dt
where  di.tablespace_name = 'SYSAUX'
and dt.table_name = di.table_name
and di.table_name like '%OPT%'
order by 1 asc
/
SQL>
INDEX_NAME                     INDEX_TYPE                  STATUS
------------------------------ --------------------------- --------
I_WRI$_OPTSTAT_AUX_ST          FUNCTION-BASED NORMAL       VALID
I_WRI$_OPTSTAT_HH_OBJ_ICOL_ST  FUNCTION-BASED NORMAL       VALID
I_WRI$_OPTSTAT_HH_ST           FUNCTION-BASED NORMAL       VALID
I_WRI$_OPTSTAT_H_OBJ#_ICOL#_ST FUNCTION-BASED NORMAL       VALID
I_WRI$_OPTSTAT_H_ST            FUNCTION-BASED NORMAL       VALID
I_WRI$_OPTSTAT_IND_OBJ#_ST     FUNCTION-BASED NORMAL       VALID
I_WRI$_OPTSTAT_IND_ST          FUNCTION-BASED NORMAL       VALID
I_WRI$_OPTSTAT_OPR_STIME       FUNCTION-BASED NORMAL       VALID
I_WRI$_OPTSTAT_TAB_OBJ#_ST     FUNCTION-BASED NORMAL       VALID
I_WRI$_OPTSTAT_TAB_ST          FUNCTION-BASED NORMAL       VALID
WRH$_OPTIMIZER_ENV_PK          NORMAL                      VALID
Finally lets see what space has been saved with a retention date of 1 day and a gather schema stats for the SYSASDM schema

exec dbms_stats.alter_stats_history_retention(1);
select dbms_stats.get_stats_history_retention from dual;
        MB SEGMENT_NAME                             SEGMEN
---------- ---------------------------------------- ------
         0 WRI$_OPTSTAT_OPR                         TABLE
         0 WRI$_OPTSTAT_AUX_HISTORY                 TABLE
         3 WRI$_OPTSTAT_TAB_HISTORY                 TABLE
         4 WRI$_OPTSTAT_IND_HISTORY                 TABLE
         8 WRI$_OPTSTAT_HISTGRM_HISTORY             TABLE
       104 WRI$_OPTSTAT_HISTHEAD_HISTORY            TABLE

        MB SEGMENT_NAME                             SEGMEN
---------- ---------------------------------------- ------
         0 WRH$_OPTIMIZER_ENV_PK                    INDEX
         0 I_WRI$_OPTSTAT_OPR_STIME                 INDEX
         0 I_WRI$_OPTSTAT_AUX_ST                    INDEX
         2 I_WRI$_OPTSTAT_IND_ST                    INDEX
         2 I_WRI$_OPTSTAT_TAB_ST                    INDEX
         3 I_WRI$_OPTSTAT_TAB_OBJ#_ST               INDEX
         4 I_WRI$_OPTSTAT_IND_OBJ#_ST               INDEX
         5 I_WRI$_OPTSTAT_H_ST                      INDEX
         9 I_WRI$_OPTSTAT_H_OBJ#_ICOL#_ST           INDEX
        41 I_WRI$_OPTSTAT_HH_ST                     INDEX
        96 I_WRI$_OPTSTAT_HH_OBJ_ICOL_ST            INDEX

Ref
====
For more information : FAQ: Automatic Statistics Collection ( Doc ID 1233203.1 )
Suggestions if Your SYSAUX Tablespace Grows Rapidly or Too Large (Doc ID 1292724.1)
https://jhdba.wordpress.com/tag/dbms_stats-purge_stats/


No comments :

Post a Comment