DATAFILE SHRINK释放系统空间
寄语:datafile Shrink来释放系统空间。下面是一些脚本,希望对大家有所帮助。
##环境##
SQL> select * from v$version;
BANNER
--------------------------------------------------------------------------------
Oracle Database 11g Enterprise Edition Release 11.2.0.4.0 - 64bit Production
PL/SQL Release 11.2.0.4.0 - Production
CORE 11.2.0.4.0 Production
TNS for IBM/AIX RISC System/6000: Version 11.2.0.4.0 - Production
NLSRTL Version 11.2.0.4.0 - Production
##查看datafile resize 最小值 (Smallest Size Poss.)##
Script for MAX-Shrink:-
set verify off
column file_name format a50 word_wrapped
column smallest format 999,990 heading "Smallest|Size|Poss."
column currsize format 999,990 heading "Current|Size"
column savings format 999,990 heading "Poss.|Savings"
break on report
compute sum of savings on report
column value new_val blksize
select value from v$parameter where name = 'db_block_size';
/
select file_name,
ceil( (nvl(hwm,1)*&&blksize)/1024/1024 ) smallest,
ceil( blocks*&&blksize/1024/1024) currsize,
ceil( blocks*&&blksize/1024/1024) -
ceil( (nvl(hwm,1)*&&blksize)/1024/1024 ) savings
from dba_data_files a,
( select file_id, max(block_id+blocks-1) hwm
from dba_extents
group by file_id ) b
where a.file_id = b.file_id(+) order by savings desc
/
Smallest
Size Current Poss.
FILE_NAME Poss. Size Savings
-------------------------------------------------- -------- -------- --------
+DATA/ggdb/datafile/bigfile_pgs_data_index.dbf 1 153,600 153,599
+DATA/ggdb/datafile/bigfile_dm_data_index.dbf 1 51,200 51,199
+DATA/ggdb/datafile/pgs_data_tbs_10 23,900 32,704 8,804
+DATA/ggdb/datafile/pgs_data_tbs_08 26,298 32,704 6,406
##查看datafile HWM和datafile tablespace_name##
column cmd format a75 word_wrapped
select 'alter database datafile '''||file_name||''' resize ' ||
ceil( (nvl(hwm,1)*&&blksize)/1024/1024 ) || 'm;' cmd
from dba_data_files a,
( select file_id, max(block_id+blocks-1) hwm
from dba_extents
group by file_id ) b
where a.file_id = b.file_id(+)
and ceil( blocks*&&blksize/1024/1024) -
ceil( (nvl(hwm,1)*&&blksize)/1024/1024 ) > 0
/
TABLESPACE_NAME FILE_NAME FILE_SIZE HWM CAN_SAVE
--------------- -------------------------------------------------- --------- ------ --------
BBMC_pgs_TEST +DATA/ggdb/datafile/BBMC_pgs_test01.dbf 346 346 0
BBMC_pgs_TEST +DATA/ggdb/datafile/BBMC_pgs_test02.dbf 329 329 0
BIONE_DATA +DATA/ggdb/datafile/bione_data_01.dbf 200 5 195
cmdc_DATA_TBS +DATA/ggdb/datafile/cmdc_data_tbs_01.dbf 32760 32561 199
##批量生成datafile resize语句##
column cmd format a75 word_wrapped
select 'alter database datafile '''||file_name||''' resize ' ||
ceil( (nvl(hwm,1)*&&blksize)/1024/1024 ) || 'm;' cmd
from dba_data_files a,
( select file_id, max(block_id+blocks-1) hwm
from dba_extents
group by file_id ) b
where a.file_id = b.file_id(+)
and ceil( blocks*&&blksize/1024/1024) -
ceil( (nvl(hwm,1)*&&blksize)/1024/1024 ) > 0
/
CMD
---------------------------------------------------------------------------
alter database datafile '+DATA/ggdb/datafile/pgs_data_tbs_16.dbf' resize 25661m;
alter database datafile '+DATA/ggdb/datafile/pgs_data_tbs_08' resize 26298m;
alter database datafile '+DATA/ggdb/datafile/pgs_data_tbs_01.dbf' resize 29565m;
alter database datafile '+DATA/ggdb/datafile/pgs_data_tbs_10.dbf' resize 32703m;
总结:DBA维护当中,多多使用脚本来提升效率。
本文参考:
How to SHRINK or Reduce the datafile size by finding the HWM (文档 ID 1600774.1)
http://blog.chinaunix.net/uid-42518-id-2404799.html
########################################################################################
版权所有,文章允许转载,但必须以链接方式注明源地址,否则追究法律责任!【QQ交流群:53993419】
QQ:14040928
本文链接:
http://blog.itpub.net/26442936/viewspace-1975163/
########################################################################################