12.2的sysaux表空间使用过大
SQL> select * from v$version;
BANNER CON_ID
-------------------------------------------------------------------------------- ----------
Oracle Database 12c Enterprise Edition Release 12.2.0.1.0 - 64bit Production 0
PL/SQL Release 12.2.0.1.0 - Production 0
CORE 12.2.0.1.0 Production 0
TNS for Linux: Version 12.2.0.1.0 - Production 0
NLSRTL Version 12.2.0.1.0 - Production 0
SQL> @tbs
Name TS Type All Size(MB) Max Size(MB) Free Size(MB) Max Free Pct. Free Max Free%
--------- ---------- -------------- -------------- -------------- --------- --------- ---------
SYSAUX PERMANENT 32,760 32,768 26 34 0 0
USERS PERMANENT 1,784 32,768 85 31,069 5 95
SYSTEM PERMANENT 860 32,768 10 31,917 1 97
R_INDEX PERMANENT 5,900 229,376 927 224,403 16 98
RICHMAN PERMANENT 3,000 196,608 1,895 195,503 63 99
UNDOTBS1 UNDO 1,600 32,768 1,560 32,728 97 100
6 rows selected.
awrinfo查看
********************************************************
(1b) SYSAUX occupants space usage (v$sysaux_occupants)
********************************************************
|
| Occupant Name Schema Name Space Usage
| -------------------- -------------------- ----------------
| SM/ADVISOR SYS 30,422.9 MB
| SM/OPTSTAT SYS 1,222.7 MB
| SM/AWR SYS 588.2 MB
| SM/OTHER SYS 152.4 MB
**********************************
(4) Space usage by non-AWR components (> 500K)
**********************************
COMPONENT MB SEGMENT_NAME SEGMENT_TYPE
--------- --------- ------------------------------------------------- -------------
NON_AWR 15,675.0 SYS.WRI$_ADV_OBJECTS TABLE
NON_AWR 8,764.0 SYS.WRI$_ADV_OBJECTS_IDX_01 INDEX
NON_AWR 5,959.0 SYS.WRI$_ADV_OBJECTS_PK INDEX
NON_AWR 488.0 SYS.I_WRI$_OPTSTAT_H_OBJ#_ICOL#_ST INDEX
NON_AWR 249.0 SYS.I_WRI$_OPTSTAT_H_ST INDEX
这里为ADVISOR功能模块导致,而且主要是WRI$_ADV_OBJECTS表及其索引
分析主要对象
SQL> COL SEGMENT_NAME FORMAT A30
SQL> COL OWNER FORMAT A10
SQL> COL TABLESPACE_NAME FORMAT A10
SQL> COL SEGMENT_TYPE FORMAT A15
SQL> SELECT * FROM (SELECT SEGMENT_NAME,OWNER,TABLESPACE_NAME,BYTES/1024/1024
2 "SIZE(MB)",SEGMENT_TYPE FROM DBA_SEGMENTS WHERE
3 TABLESPACE_NAME='SYSAUX' ORDER BY BYTES DESC) WHERE ROWNUM<=10;
SEGMENT_NAME OWNER Name SIZE(MB) SEGMENT_TYPE
------------------------------ ---------- ---------- ---------- ---------------
WRI$_ADV_OBJECTS SYS SYSAUX 15675 TABLE
WRI$_ADV_OBJECTS_IDX_01 SYS SYSAUX 8764 INDEX
WRI$_ADV_OBJECTS_PK SYS SYSAUX 5959 INDEX
I_WRI$_OPTSTAT_H_OBJ#_ICOL#_ST SYS SYSAUX 488 INDEX
I_WRI$_OPTSTAT_H_ST SYS SYSAUX 249 INDEX
SYS_LOB0000007350C00005$$ SYS SYSAUX 133.1875 LOBSEGMENT
SYS_LOB0000010641C00038$$ SYS SYSAUX 110.1875 LOBSEGMENT
WRH$_SQL_PLAN SYS SYSAUX 64 TABLE
I_WRI$_OPTSTAT_HH_OBJ_ICOL_ST SYS SYSAUX 51 INDEX
SYS_LOB0000067470C00006$$ MDSYS SYSAUX 50.1875 LOBSEGMENT
10 rows selected.
这里也比较明显主要是由于WRI$_ADV_OBJECTS表及其index占用空间较多导致.WRI$_ADV_OBJECTS表主要是12.2新特性Optimizer Statistics Advisor功能使用到的表,用来存储相关数据
清理WRI$_ADV_OBJECTS相关数据
DECLARE
v_tname VARCHAR2(32767);
BEGIN
v_tname := 'AUTO_STATS_ADVISOR_TASK';
DBMS_STATS.DROP_ADVISOR_TASK(v_tname);
END;
/
EXEC DBMS_STATS.INIT_PACKAGE();
ALTER TABLE WRI$_ADV_OBJECTS MOVE;
ALTER INDEX WRI$_ADV_OBJECTS_IDX_01 REBUILD;
ALTER INDEX WRI$_ADV_OBJECTS_PK REBUILD;
禁用Optimizer Statistics Advisor Task
DECLARE
filter1 CLOB;
BEGIN
filter1 := DBMS_STATS.CONFIGURE_ADVISOR_RULE_FILTER('AUTO_STATS_ADVISOR_TASK','EXECUTE',NULL,'DISABLE');
END;
/
参考文档:SYSAUX Tablespace Grows Rapidly After Upgrading Database to 12.2.0.1 Due To Statistics Advisor (Doc ID 2305512.1)