Your SYSAUX is bigger than the rest of database?
It’s not uncommon to “old” databases, usually bad administrated. Some databases configuration must cause this situation.
The general indication is to review stats and reports retention of objects and database.
But if you need to clean it now, how to do?
1) PURGE_STATS. It’s recommended to execute in smaller steps. Otherwise the RBS tablespace will be blown up.
2) Oracle is sometimes building new extents for SYSAUX stats table in other tablespaces. They will be moved back to the SYSAUX tablespace.
3) The Index rebuild will decrease the size of the indexes. They are mostly larger as the raw data.
4) The Indexes are partly function bases. Therefore it is imported in which order the index rebuild will be done. Otherwise you have to reexecute this steps again and again.
Going practical, I used the follow:
exec DBMS_STATS.PURGE_STATS(SYSDATE-180); exec DBMS_STATS.PURGE_STATS(SYSDATE-160); exec DBMS_STATS.PURGE_STATS(SYSDATE-140); exec DBMS_STATS.PURGE_STATS(SYSDATE-120); exec DBMS_STATS.PURGE_STATS(SYSDATE-100); exec DBMS_STATS.PURGE_STATS(SYSDATE-80); exec DBMS_STATS.PURGE_STATS(SYSDATE-60); exec DBMS_STATS.PURGE_STATS(SYSDATE-40); exec DBMS_STATS.PURGE_STATS(SYSDATE-20); exec DBMS_STATS.PURGE_STATS(SYSDATE-7); 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; Alter index SYS.I_WRI$_OPTSTAT_IND_ST rebuild TABLESPACE SYSAUX; Alter index SYS.I_WRI$_OPTSTAT_IND_OBJ#_ST rebuild TABLESPACE SYSAUX; Alter index SYS.I_WRI$_OPTSTAT_HH_ST rebuild TABLESPACE SYSAUX; Alter index SYS.I_WRI$_OPTSTAT_HH_OBJ_ICOL_ST rebuild TABLESPACE SYSAUX; Alter index SYS.I_WRI$_OPTSTAT_TAB_ST rebuild TABLESPACE SYSAUX; Alter index SYS.I_WRI$_OPTSTAT_TAB_OBJ#_ST rebuild TABLESPACE SYSAUX; Alter index SYS.I_WRI$_OPTSTAT_OPR_STIME rebuild TABLESPACE SYSAUX;
Matheus.
Pingback: Statistics not Being Auto Purged – Splitting Purge – |GREP ORA
Thank you Matheus! This helped me a lot!
Abraços,
Maranhão