标签云
asm恢复 bbed bootstrap$ dul In Memory kcbzib_kcrsds_1 kccpb_sanity_check_2 MySQL恢复 ORA-00312 ORA-00607 ORA-00704 ORA-00742 ORA-01110 ORA-01555 ORA-01578 ORA-08103 ORA-600 2131 ORA-600 2662 ORA-600 2663 ORA-600 3020 ORA-600 4000 ORA-600 4137 ORA-600 4193 ORA-600 4194 ORA-600 16703 ORA-600 kcbzib_kcrsds_1 ORA-600 KCLCHKBLK_4 ORA-15042 ORA-15196 ORACLE 12C oracle dul ORACLE PATCH Oracle Recovery Tools oracle加密恢复 oracle勒索 oracle勒索恢复 oracle异常恢复 ORACLE恢复 Oracle 恢复 ORACLE数据库恢复 oracle 比特币 OSD-04016 YOUR FILES ARE ENCRYPTED 勒索恢复 比特币加密文章分类
- Others (2)
- 中间件 (2)
- WebLogic (2)
- 操作系统 (102)
- 数据库 (1,700)
- DB2 (22)
- MySQL (74)
- Oracle (1,561)
- Data Guard (52)
- EXADATA (8)
- GoldenGate (24)
- ORA-xxxxx (159)
- ORACLE 12C (72)
- ORACLE 18C (6)
- ORACLE 19C (15)
- ORACLE 21C (3)
- Oracle 23ai (8)
- Oracle ASM (68)
- Oracle Bug (8)
- Oracle RAC (53)
- Oracle 安全 (6)
- Oracle 开发 (28)
- Oracle 监听 (28)
- Oracle备份恢复 (571)
- Oracle安装升级 (94)
- Oracle性能优化 (62)
- 专题索引 (5)
- 勒索恢复 (81)
- PostgreSQL (18)
- PostgreSQL恢复 (6)
- SQL Server (27)
- SQL Server恢复 (8)
- TimesTen (7)
- 达梦数据库 (2)
- 生活娱乐 (2)
- 至理名言 (11)
- 虚拟化 (2)
- VMware (2)
- 软件开发 (37)
- Asp.Net (9)
- JavaScript (12)
- PHP (2)
- 小工具 (20)
-
最近发表
- Oracle 19c 202501补丁(RUs+OJVM)
- 避免 19c 数据库性能问题需要考虑的事项 (Doc ID 3050476.1)
- Bug 21915719 Database hang or may fail to OPEN in 12c IBM AIX or HPUX Itanium – ORA-742, DEADLOCK or ORA-600 [kcrfrgv_nextlwn_scn] ORA-600 [krr_process_read_error_2]
- ORA-600 ktuPopDictI_1恢复
- impdp导入数据丢失sys授权问题分析
- impdp 创建index提示ORA-00942: table or view does not exist
- 数据泵导出 (expdp) 和导入 (impdp)工具性能降低分析参考
- 19c非归档数据库断电导致ORA-00742故障恢复
- Oracle 19c – 手动升级到 Non-CDB Oracle Database 19c 的完整核对清单
- sqlite数据库简单操作
- Oracle 暂定和恢复功能
- .pzpq扩展名勒索恢复
- Oracle read only用户—23ai新特性:只读用户
- 迁移awr快照数据到自定义表空间
- .hmallox加密mariadb/mysql数据库恢复
- 2025年首个故障恢复—ORA-600 kcbzib_kcrsds_1
- 第一例Oracle 21c恢复咨询
- ORA-15411: Failure groups in disk group DATA have different number of disks.
- 断电引起的ORA-08102: 未找到索引关键字, 对象号 39故障处理
- ORA-00227: corrupt block detected in control file
标签归档:SYSAUX
WRI$_ADV_OBJECTS表过大,导致SYSAUX表空间不足
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)