4.1 KiB
4.1 KiB
# 查询表空间
SELECT TABLESPACE_NAME "表空间",
To_char(Round(BYTES / 1024, 2), '99990.00')
|| '' "实有",
To_char(Round(FREE / 1024, 2), '99990.00')
|| 'G' "现有",
To_char(Round(( BYTES - FREE ) / 1024, 2), '99990.00')
|| 'G' "使用",
To_char(Round(10000 * USED / BYTES) / 100, '99990.00')
|| '%' "比例"
FROM (SELECT A.TABLESPACE_NAME TABLESPACE_NAME,
Floor(A.BYTES / ( 1024 * 1024 )) BYTES,
Floor(B.FREE / ( 1024 * 1024 )) FREE,
Floor(( A.BYTES - B.FREE ) / ( 1024 * 1024 )) USED
FROM (SELECT TABLESPACE_NAME TABLESPACE_NAME,
Sum(BYTES) BYTES
FROM DBA_DATA_FILES
GROUP BY TABLESPACE_NAME) A,
(SELECT TABLESPACE_NAME TABLESPACE_NAME,
Sum(BYTES) FREE
FROM DBA_FREE_SPACE
GROUP BY TABLESPACE_NAME) B
WHERE A.TABLESPACE_NAME = B.TABLESPACE_NAME)
--WHERE TABLESPACE_NAME LIKE 'CDR%' --这一句用于指定表空间名称
ORDER BY Floor(10000 * USED / BYTES) DESC;
set linesize 140 pagesize 10000
col "Status" for a10
col "Name" for a25
col "Type" for a10
col "Extent" for a15
col "Size(M)" for a15
col "Used(M)" for a15
col "Used(%)" for a20
col "Maxused(%)" for a20
SELECT d.status "Status", d.tablespace_name "Name", d.contents "Type", d.extent_management "Extent",
TO_CHAR(NVL(a.bytes / 1024 / 1024, 0),'99,999,990') "Size(M)",
TO_CHAR(NVL(a.bytes - NVL(f.bytes, 0), 0)/1024/1024,'999,999,999') "Used(M)",
TO_CHAR(NVL((a.bytes - NVL(f.bytes, 0)) / a.bytes * 100, 0), '900.00') "Used(%)",
TO_CHAR(100-((a.maxbytes - a.bytes + f.bytes) / a.maxbytes * 100), '900.00') "Maxused(%)"
FROM sys.dba_tablespaces d,
(select tablespace_name, sum(bytes) bytes,sum(decode(autoextensible, 'YES',maxbytes,'NO', bytes)) maxbytes from dba_data_files group by tablespace_name) a,
(select tablespace_name, sum(bytes) bytes from dba_free_space group by tablespace_name) f
WHERE d.tablespace_name = a.tablespace_name(+) AND d.tablespace_name = f.tablespace_name(+) AND NOT
(d.extent_management like 'LOCAL' AND d.contents like 'TEMPORARY')
UNION ALL
SELECT d.status "Status", d.tablespace_name "Name", d.contents "Type", d.extent_management "Extent",
TO_CHAR(NVL(a.bytes / 1024 / 1024, 0),'99,999,999') "Size(M)",
TO_CHAR(NVL(t.bytes,0)/1024/1024,'999,999,999') "Used(M)",
TO_CHAR(NVL(t.bytes / a.bytes * 100, 0), '990.00') "Used(%)" ,
TO_CHAR(NVL(t.bytes / a.maxbytes * 100, 0), '990.00') "Maxused(%)"
FROM sys.dba_tablespaces d,
(select tablespace_name, sum(bytes) bytes,sum(decode(autoextensible, 'YES',maxbytes,'NO', bytes)) maxbytes from dba_temp_files group by tablespace_name) a,
(select tablespace_name, sum(bytes_cached) bytes from v$temp_extent_pool group by tablespace_name) t
WHERE d.tablespace_name = a.tablespace_name(+) AND d.tablespace_name = t.tablespace_name(+) AND
d.extent_management like 'LOCAL' AND d.contents like 'TEMPORARY'
ORDER BY 7;
# 查询表空间文件及目录
select
b.file_name 物理文件名,
b.tablespace_name 表空间,
b.bytes/1024/1024 大小M,
(b.bytes-sum(nvl(a.bytes,0)))/1024/1024 已使用M,
substr((b.bytes-sum(nvl(a.bytes,0)))/(b.bytes)*100,1,5) 利用率
from dba_free_space a,dba_data_files b
where a.file_id=b.file_id
group by b.tablespace_name,b.file_name,b.bytes
order by b.tablespace_name;
select tablespace_name,file_id,bytes/1024/1024,file_name from dba_data_files order by file_id;
# 增加表空间文件
ALTER TABLESPACE [表空间名称] ADD DATAFILE '数据文件路径' SIZE 8G;
ALTER TABLESPACE [表空间名称] ADD DATAFILE '+DATA' SIZE 8G REUSE AUTOEXTEND ON;
# 查询归档日志空间使用情况
select to_char(next_time, 'yyyy-mm-dd') hourtime, round(sum(blocks * block_size) / 1024 / 1024 / 1024) archlog_GB from v$archived_log where dest_id = 1 and next_time > sysdate - 15 group by to_char(next_time, 'yyyy-mm-dd') order by to_char(next_time, 'yyyy-mm-dd');