首页
首页
文章目录
  1. 简介
  2. 处理思路

oracle 清理SYSAUX表空间

简介

oracle 清理SYSAUX表空间

处理思路

1、查询表空间使用情况

1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
SELECT UPPER(F.TABLESPACE_NAME) "表空间名", 
D.TOT_GROOTTE_MB "表空间大小(M)",
D.TOT_GROOTTE_MB - F.TOTAL_BYTES "已使用空间(M)",
TO_CHAR(ROUND((D.TOT_GROOTTE_MB - F.TOTAL_BYTES) / D.TOT_GROOTTE_MB * 100,2),'990.99') "使用比",
F.TOTAL_BYTES "空闲空间(M)",
F.MAX_BYTES "最大块(M)"
FROM (SELECT TABLESPACE_NAME,
ROUND(SUM(BYTES) / (1024 * 1024), 2) TOTAL_BYTES,
ROUND(MAX(BYTES) / (1024 * 1024), 2) MAX_BYTES
FROM SYS.DBA_FREE_SPACE
GROUP BY TABLESPACE_NAME) F,
(SELECT DD.TABLESPACE_NAME,
ROUND(SUM(DD.BYTES) / (1024 * 1024), 2) TOT_GROOTTE_MB
FROM SYS.DBA_DATA_FILES DD
GROUP BY DD.TABLESPACE_NAME) D
WHERE D.TABLESPACE_NAME = F.TABLESPACE_NAME
ORDER BY 4 DESC;

2、查看一下表空间是否开启自动扩展功能

1
2
3
4
SELECT T.TABLESPACE_NAME,D.FILE_NAME,D.AUTOEXTENSIBLE,D.BYTES,D.MAXBYTES,D.STATUS 
FROM DBA_TABLESPACES T,DBA_DATA_FILES D
WHERE T.TABLESPACE_NAME =D.TABLESPACE_NAME
ORDER BY TABLESPACE_NAME,FILE_NAME;

3、查询下SYSTEM和SYSAUX表空间的使用率

1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18
19
20
21
22
23
24
25
26
27
28
29
30
31
32
33
34
35
36
37
38
SELECT * FROM ( 
SELECT D.TABLESPACE_NAME,
SPACE || 'M' "SUM_SPACE(M)",
BLOCKS "SUM_BLOCKS",
SPACE - NVL (FREE_SPACE, 0) || 'M' "USED_SPACE(M)",
ROUND ( (1 - NVL (FREE_SPACE, 0) / SPACE) * 100, 2) || '%'
"USED_RATE(%)",
FREE_SPACE || 'M' "FREE_SPACE(M)"
FROM ( SELECT TABLESPACE_NAME,
ROUND (SUM (BYTES) / (1024 * 1024), 2) SPACE,
SUM (BLOCKS) BLOCKS
FROM DBA_DATA_FILES
GROUP BY TABLESPACE_NAME) D,
( SELECT TABLESPACE_NAME,
ROUND (SUM (BYTES) / (1024 * 1024), 2) FREE_SPACE
FROM DBA_FREE_SPACE
GROUP BY TABLESPACE_NAME) F
WHERE D.TABLESPACE_NAME = F.TABLESPACE_NAME(+)
UNION ALL
SELECT D.TABLESPACE_NAME,
SPACE || 'M' "SUM_SPACE(M)",
BLOCKS SUM_BLOCKS,
USED_SPACE || 'M' "USED_SPACE(M)",
ROUND (NVL (USED_SPACE, 0) / SPACE * 100, 2) || '%' "USED_RATE(%)",
NVL (FREE_SPACE, 0) || 'M' "FREE_SPACE(M)"
FROM ( SELECT TABLESPACE_NAME,
ROUND (SUM (BYTES) / (1024 * 1024), 2) SPACE,
SUM (BLOCKS) BLOCKS
FROM DBA_TEMP_FILES
GROUP BY TABLESPACE_NAME) D,
( SELECT TABLESPACE_NAME,
ROUND (SUM (BYTES_USED) / (1024 * 1024), 2) USED_SPACE,
ROUND (SUM (BYTES_FREE) / (1024 * 1024), 2) FREE_SPACE
FROM V$TEMP_SPACE_HEADER
GROUP BY TABLESPACE_NAME) F
WHERE D.TABLESPACE_NAME = F.TABLESPACE_NAME(+)
ORDER BY 1)
WHERE TABLESPACE_NAME IN ('SYSAUX','SYSTEM');

4、查看下使用SYSTEM和SYSAUX表空间的比较大的表有哪些

1
2
3
4
select * from (
select segment_name,sum(bytes)/1024/1024 total_mb,tablespace_name from dba_segments where tablespace_name in
('SYSTEM','SYSAUX') group by segment_name,tablespace_name order by 2 desc)
where rownum <=20;

5、可见,大表大部分都是AUD $和$ WRH开头的AWR基表,AUD $使用SYSTEM表空间,AWR的基表使用SYSAUX表空间,下面再查看下SYSAUX表空间的使用情况,可以通过V $ SYSAUX_OCCUPANTS视图查询到。

1
2
3
4
5
6
SELECT occupant_name "Item", 
space_usage_kbytes / 1048576 "Space Used (GB)",
schema_name "Schema",
move_procedure "Move Procedure"
FROM v$sysaux_occupants
ORDER BY 1 ;

6、首先清理审计的数据,如果要保留部分AUD $里面记录的审计数据,可以把想要的数据插入到一张临时表,然后直接截断这张表就可以了,截断操作会直接回收AUD $占用的空间。
但由于是正式库,怕truncate操作会带来其他的一些问题,不直接做truncate,而是执行以下命令:

1
2
3
4
5
6
truncate table sys.aud$ reuse storage;
alter table sys.aud$ deallocate unused keep 8640m;
alter table sys.aud$ deallocate unused keep 7000m;
alter table sys.aud$ deallocate unused keep 6000m;
...
alter table sys.aud$ deallocate unused keep 10m;

truncate过程1-2分钟之内结束,最后sys.aud$变成10M。

解释:思路就是在前面执行truncate的时候,降低了HWM但没释放空间。 alter table sys.aud$ deallocate unused keep 6000m; 这个命令,就是一点一点释放HWM之上的自由空间,最后保留10m空间,因为我们这个表是要继续使用,而不是要删除。

7、清理WRH$表 生成删除段内容语句

1
2
3
4
5
6
select distinct 'truncate table '||segment_name||';',s.bytes/1024/1024
from dba_segments s
where s.segment_name like 'WRH$%'
and segment_type in ('TABLE PARTITION', 'TABLE')
and s.bytes/1024/1024>100
order by s.bytes/1024/1024/1024 desc;

8、删除表

1
2
3
4
5
6
7
8
9
10
truncate table WRH$_ACTIVE_SESSION_HISTORY;
truncate table WRH$_EVENT_HISTOGRAM;
truncate table WRH$_LATCH;
truncate table WRH$_SQLSTAT;
truncate table WRH$_SYSSTAT;
truncate table WRH$_PARAMETER;
truncate table WRH$_SQL_PLAN;
truncate table WRH$_LATCH_MISSES_SUMMARY;
truncate table WRH$_SEG_STAT;
truncate table WRH$_SYSTEM_EVENT;

9、验证表空间

1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
SELECT UPPER(F.TABLESPACE_NAME) "表空间名", 
D.TOT_GROOTTE_MB "表空间大小(M)",
D.TOT_GROOTTE_MB - F.TOTAL_BYTES "已使用空间(M)",
TO_CHAR(ROUND((D.TOT_GROOTTE_MB - F.TOTAL_BYTES) / D.TOT_GROOTTE_MB * 100,2),'990.99') "使用比",
F.TOTAL_BYTES "空闲空间(M)",
F.MAX_BYTES "最大块(M)"
FROM (SELECT TABLESPACE_NAME,
ROUND(SUM(BYTES) / (1024 * 1024), 2) TOTAL_BYTES,
ROUND(MAX(BYTES) / (1024 * 1024), 2) MAX_BYTES
FROM SYS.DBA_FREE_SPACE
GROUP BY TABLESPACE_NAME) F,
(SELECT DD.TABLESPACE_NAME,
ROUND(SUM(DD.BYTES) / (1024 * 1024), 2) TOT_GROOTTE_MB
FROM SYS.DBA_DATA_FILES DD
GROUP BY DD.TABLESPACE_NAME) D
WHERE D.TABLESPACE_NAME = F.TABLESPACE_NAME
ORDER BY 4 DESC;

以上,

End

支持一下
扫一扫,我会更有动力更新
  • 微信扫一扫
  • 支付宝扫一扫