SYSAUX表空间收缩

教程发布:风哥 教程分类:ITPUX技术网 更新日期:2022-02-12 浏览学习:43

--一.清理SYSAUX下的历史统计信息
--1.将历史统计信息保留时间设为无限
--dbms_stats.alter_stats_history_retention();
BEGIN
dbms_stats.alter_stats_history_retention(-1);
END;
select dbms_stats.get_stats_history_availability from dual;
select dbms_stats.get_stats_history_retention from dual;
--2.truncate较大的TABLE
truncate table sys.WRI$_OPTSTAT_HISTHEAD_HISTORY;
truncate table sys.WRI$_OPTSTAT_HISTGRM_HISTORY;
--3.清理历史统计信息
exec dbms_stats.purge_stats(sysdate-101);
exec dbms_stats.purge_stats(sysdate-51);
exec dbms_stats.purge_stats(sysdate-5);
--4.将历史统计信息保留时间设为10 天
BEGIN
dbms_stats.alter_stats_history_retention(8);
END;
--5.将历史统计信息相关的表进行MOVE
alter table sys.WRI$_OPTSTAT_HISTHEAD_HISTORY move tablespace sysaux;
alter index sys.I_WRI$_OPTSTAT_HH_OBJ_ICOL_ST rebuild online;
alter index sys.I_WRI$_OPTSTAT_HH_ST rebuild online;
alter table sys.WRI$_OPTSTAT_HISTGRM_HISTORY move tablespace sysaux;
alter index sys.I_WRI$_OPTSTAT_H_OBJ#_ICOL#_ST rebuild online;
alter index sys.I_WRI$_OPTSTAT_H_ST rebuild online;
alter table sys.WRI$_OPTSTAT_IND_HISTORY move tablespace sysaux;
alter index sys.I_WRI$_OPTSTAT_IND_OBJ#_ST rebuild online;
alter index sys.I_WRI$_OPTSTAT_IND_ST rebuild online;
alter table sys.WRI$_OPTSTAT_TAB_HISTORY move tablespace sysaux;
alter index sys.I_WRI$_OPTSTAT_TAB_OBJ#_ST rebuild online;
alter index sys.I_WRI$_OPTSTAT_TAB_ST rebuild online;
ALTER TABLE SYS.WRI$_OPTSTAT_OPR MOVE TABLESPACE SYSAUX;
ALTER TABLE SYS.WRI$_OPTSTAT_AUX_HISTORY MOVE TABLESPACE SYSAUX;
ALTER INDEX SYS.I_WRI$_OPTSTAT_AUX_ST REBUILD ONLINE;
ALTER INDEX SYS.I_WRI$_OPTSTAT_OPR_STIME REBUILD ONLINE;
--6.对MOVE表的统计信息进行收集
EXEC dbms_stats.gather_table_stats(ownname => 'SYS',tabname => 'WRI$_OPTSTAT_HISTHEAD_HISTORY',cascade => TRUE);
EXEC dbms_stats.gather_table_stats(ownname => 'SYS',tabname => 'WRI$_OPTSTAT_HISTGRM_HISTORY',cascade => TRUE);
EXEC dbms_stats.gather_table_stats(ownname => 'SYS',tabname => 'WRI$_OPTSTAT_IND_HISTORY',cascade => TRUE);
EXEC dbms_stats.gather_table_stats(ownname => 'SYS',tabname => 'WRI$_OPTSTAT_TAB_HISTORY',cascade => TRUE);
EXEC dbms_stats.gather_table_stats(ownname => 'SYS',tabname => 'WRI$_OPTSTAT_OPR',cascade => TRUE);
EXEC dbms_stats.gather_table_stats(ownname => 'SYS',tabname => 'WRI$_OPTSTAT_AUX_HISTORY',cascade => TRUE);
--二.清理SYSAUX下的无效ASH信息
--1.检查是否有无效的ASH信息
select count(*)
from sys.wrh$_active_session_history a
where not exists (select 1
from sys.wrm$_snapshot b
where a.snap_id = b.snap_id
and a.dbid = b.dbid
and a.instance_number = b.instance_number);
--2.清理无效的ASH信息
delete
from sys.wrh$_active_session_history a
where not exists (select 1
from sys.wrm$_snapshot b
where a.snap_id = b.snap_id
and a.dbid = b.dbid
and a.instance_number = b.instance_number);
--3.对ASH表清理后的碎片整理
alter table sys.wrh$_active_session_history enable row movement;
alter table sys.wrh$_active_session_history shrink space cascade;
alter table sys.wrh$_active_session_history disable row movement;
--4.收集碎片整理后表的统计信息
EXEC dbms_stats.gather_table_stats(ownname => 'SYS',tabname => 'WRH$_ACTIVE_SESSION_HISTORY',cascade => TRUE);
--5.检查表空间可收缩的的位置
col RESIZECMD for a110
set linesize 1000;
col NAME for a40
select a.FILE#,
a.NAME,
a.BYTES / 1024 / 1024 mb,
ceil(HWM * A.BLOCK_SIZE) / 1024 / 1024 RESIZETO,
'ALTER DATABASE DATAFILE ''' || A.NAME || ''' RESIZE ' ||
(trunc(CEIL(HWM * A.BLOCK_SIZE) / 1024 / 1024)+20) || 'M;' RESIZECMD
from v$datafile a,
(SELECT C.file_id, MAX(C.block_id + C.blocks-1) HWM
FROM DBA_EXTENTS C
GROUP BY FILE_ID) B
WHERE A.FILE# = B.FILE_ID
--AND a.TS#=392
ORDER BY 5;

SELECT * from v$tablespace t WHERE t.NAME='SYSAUX';
--三.SYSAUX清理后的检查
--1.清理后的无效INDEX检查
select * from dba_indexes where status<>'VALID' AND STATUS<>'N/A';
SELECT * FROM DBA_IND_PARTITIONS WHERE STATUS<>'USABLE' AND STATUS<>'N/A';
SELECT * FROM DBA_IND_SUBPARTITIONS WHERE STATUS<>'USABLE';
--上面语句应均无数据返回,如有则对这些INDEX进行重建
--2.清理后的INDEX并行度检查
select * from dba_indexes where degree not in ('1','0','DEFAULT');

本文标签:
本文标题:SYSAUX表空间收缩
网站声明:本文由风哥整理发布,转载请保留此段声明,本站所有内容将不对其使用后果做任何承诺,请读者谨慎使用!
【上一篇】
【下一篇】