oracle 表空間管理相關(guān)
通過(guò)以下幾步基本可以查看表空間情況以及處理表空間不足問(wèn)題。
ASM相關(guān)
查看asm空間
select group_number,name,total_mb,free_mb from v$asm_diskgroup;
表空間相關(guān)
表空間使用率
注:對(duì)于12c多租戶數(shù)據(jù)庫(kù),需要先切換至你需要查詢(xún)的pdb下
方案一:
set linesize 200 set pages 2000 col TABLESPACENAME for a30 select substr(a.TABLESPACE_NAME,1,30) TablespaceName, sum(a.bytes/1024/1024) as "Totle_size(M)", sum(nvl(b.free_space1/1024/1024,0)) as "Free_space(M)", sum(a.bytes/1024/1024)-sum(nvl(b.free_space1/1024/1024,0)) as "Used_space(M)", round((sum(a.bytes/1024/1024)-sum(nvl(b.free_space1/1024/1024,0))) *100/sum(a.bytes/1024/1024),2) as "Used_percent%" from dba_data_files a,(select sum(nvl(bytes,0)) free_space1,file_id from dba_free_space group by file_id) b where a.file_id = b.file_id(+) group by a.TABLESPACE_NAME order by "Used_percent%";
方案二:(包含了臨時(shí)表空間) select * from ( Select a.tablespace_name, to_char(a.bytes/1024/1024,'99,999.999') total_bytes, to_char(b.bytes/1024/1024,'99,999.999') free_bytes, to_char(a.bytes/1024/1024 - b.bytes/1024/1024,'99,999.999') use_bytes, to_char((1 - b.bytes/a.bytes)*100,'99.99') || '%' use from (select tablespace_name, sum(bytes) bytes from dba_data_files group by tablespace_name) a, (select tablespace_name, sum(bytes) bytes from dba_free_space group by tablespace_name) b where a.tablespace_name = b.tablespace_name union all select c.tablespace_name, to_char(c.bytes/1024/1024,'99,999.999') total_bytes, to_char( (c.bytes-d.bytes_used)/1024/1024,'99,999.999') free_bytes, to_char(d.bytes_used/1024/1024,'99,999.999') use_bytes, to_char(d.bytes_used*100/c.bytes,'99.99') || '%' use from (select tablespace_name,sum(bytes) bytes from dba_temp_files group by tablespace_name) c, (select tablespace_name,sum(bytes_cached) bytes_used from v$temp_extent_pool group by tablespace_name) d where c.tablespace_name = d.tablespace_name );
查看數(shù)據(jù)文件
set linesize 300 SEt pagesize 500 col file_name format a80 col TABLESPACE_NAME for a30 select tablespace_name,file_id,status,bytes/1024/1024 FileSizeM,file_name from dba_data_files order by tablespace_name;
查看表空間的擴(kuò)展方式
set linesize 120 select TABLESPACE_NAME, BLOCK_SIZE, EXTENT_MANAGEMENT, SEGMENT_SPACE_MANAGEMENT from dba_tablespaces;
查看數(shù)據(jù)文件擴(kuò)展方式
set linesize 300 set pagesize 500 col FILE_NAME for a60 col TABLESPACE_NAME for a30 select file_id,file_name,tablespace_name,autoextensible from dba_data_files order by file_id;
查看用戶默認(rèn)表空間
set lines 200 set pages 2000 col username for a20 col default_tablespace for a30 col temporary_tablespace for a30 select username, default_tablespace, temporary_tablespace from dba_users;
表空間、數(shù)據(jù)文件修改
進(jìn)行表空間擴(kuò)展
通過(guò)添加數(shù)據(jù)文件擴(kuò)展表空間
alter tablespace users add datafile '+DATA/GNNT/DATAFILE/users08.dbf' SIZE 5G autoextend on NEXT 50M maxsize 31G; 建議11c rac數(shù)據(jù)庫(kù)添加數(shù)據(jù)庫(kù)文件不必自定義數(shù)據(jù)文件名,由數(shù)據(jù)庫(kù)文件系統(tǒng)自動(dòng)生成 alter tablespace users add datafile size xxxG;
修改數(shù)據(jù)文件大小
alter database datafile '+DATA/GNNT/DATAFILE/users08.dbf' RESIZE 10G;
修改數(shù)據(jù)文件的自動(dòng)增長(zhǎng)值
alter database datafile '+DATA/GNNT/DATAFILE/users08.dbf'autoextend on NEXT 5G;
關(guān)閉數(shù)據(jù)文件的自動(dòng)增長(zhǎng)
alter database datafile '+DATA/GNNT/DATAFILE/users08.dbf' autoextend off;
作者:運(yùn)維·拖拉斯基
作者水平很低, 如果有錯(cuò)誤及時(shí)指出, 如果你覺(jué)得本文寫(xiě)的好請(qǐng)點(diǎn)一波贊~(≧▽≦)/~
出處:http://www.rzrgm.cn/-abm/
本文版權(quán)歸作者所有,歡迎轉(zhuǎn)載,但未經(jīng)作者同意必須保留此段聲明,且在文章頁(yè)面明顯位置給出原文連接,否則保留追究法律責(zé)任的權(quán)利。
浙公網(wǎng)安備 33010602011771號(hào)