<返回更多

一文看懂Oracle查询表空间的每日增长量和历史情况统计

2019-10-14    
加入收藏

概述

今天主要总结一下Oracle表空间每日增长和历史情况统计的一些脚本,仅供参考。


11g统计表空间的每日增长量

SELECT a.snap_id,
 c.tablespace_name ts_name,
 to_char(to_date(a.rtime, 'mm/dd/yyyy hh24:mi:ss'),
 'yyyy-mm-dd hh24:mi') rtime,
 round(a.tablespace_size * c.block_size / 1024 / 1024, 2) ts_size_mb,
 round(a.tablespace_usedsize * c.block_size / 1024 / 1024, 2) ts_used_mb,
 round((a.tablespace_size - a.tablespace_usedsize) * c.block_size / 1024 / 1024,
 2) ts_free_mb,
 round(a.tablespace_usedsize / a.tablespace_size * 100, 2) pct_used
 FROM dba_hist_tbspc_space_usage a,
 (SELECT tablespace_id,
 substr(rtime, 1, 10) rtime,
 max(snap_id) snap_id
 FROM dba_hist_tbspc_space_usage nb
 group by tablespace_id, substr(rtime, 1, 10)) b,
 dba_tablespaces c,
 v$tablespace d
 where a.snap_id = b.snap_id
 and a.tablespace_id = b.tablespace_id
 and a.tablespace_id = d.TS#
 and d.NAME = c.tablespace_name
 and to_date(a.rtime, 'mm/dd/yyyy hh24:mi:ss') >= sysdate - 30
 order by a.tablespace_id, to_date(a.rtime, 'mm/dd/yyyy hh24:mi:ss') desc;
一文看懂Oracle查询表空间的每日增长量和历史情况统计

 


12c统计表空间的每日增长量

SELECT a.snap_id,
 a.con_id,
 e.name pdbname,
 c.tablespace_name ts_name,
 to_char(to_date(a.rtime, 'mm/dd/yyyy hh24:mi:ss'), 'yyyy-mm-dd hh24:mi') rtime,
 round(a.tablespace_size * c.block_size / 1024 / 1024, 2) ts_size_mb,
 round(a.tablespace_usedsize * c.block_size / 1024 / 1024, 2) ts_used_mb,
 round((a.tablespace_size - a.tablespace_usedsize) * c.block_size / 1024 / 1024,
 2) ts_free_mb,
 round(a.tablespace_usedsize / a.tablespace_size * 100, 2) pct_used
 FROM cdb_hist_tbspc_space_usage a, 
 (SELECT tablespace_id,
 nb.con_id,
 substr(rtime, 1, 10) rtime,
 max(snap_id) snap_id
 FROM dba_hist_tbspc_space_usage nb
 group by tablespace_id, nb.con_id,substr(rtime, 1, 10)) b,
 cdb_tablespaces c,
 v$tablespace d,
 V$CONTAINERS e
 where a.snap_id = b.snap_id
 and a.tablespace_id = b.tablespace_id
 and a.con_id=b.con_id
 and a.con_id=c.con_id
 and a.con_id=d.con_id
 and a.con_id=e.con_id
 and a.tablespace_id=d.TS#
 and d.NAME=c.tablespace_name
 and to_date(a.rtime, 'mm/dd/yyyy hh24:mi:ss') >=sysdate-30
 order by a.CON_ID,a.tablespace_id,to_date(a.rtime, 'mm/dd/yyyy hh24:mi:ss') desc;

估算oracle 数据库,数据库对象历史增长情况

--最近七天数据库的增长情况,这个只是一个估算值。
select sum(space_used_total) / 1024 / 1024 / 1024 "last 7 days db increase - G"
 from dba_hist_seg_stat s, dba_hist_seg_stat_obj o, dba_hist_snapshot sn
 where s.obj# = o.obj#
 and sn.snap_id = s.snap_id
 and begin_interval_time > sysdate - 8
 order by begin_interval_time
一文看懂Oracle查询表空间的每日增长量和历史情况统计

 


查看数据库历史增长情况

此处是通过计算数据库所有表空间的历史增长情况来计算数据库历史情况。

--不含undo和temp
with tmp as (
select rtime,sum(tablespace_usedsize_kb) tablespace_usedsize_kb, sum(tablespace_size_kb) tablespace_size_kb 
from (select rtime, e.tablespace_id, (e.tablespace_usedsize)*(f.block_size)/1024 tablespace_usedsize_kb, 
(e.tablespace_size)*(f.block_size)/1024 tablespace_size_kb from dba_hist_tbspc_space_usage e, dba_tablespaces f, v$tablespace g
 where e.tablespace_id = g.TS# and f.tablespace_name = g.NAME and f.contents not in ('TEMPORARY','UNDO')) group by rtime) 
select tmp.rtime, tablespace_usedsize_kb, tablespace_size_kb,(tablespace_usedsize_kb - LAG(tablespace_usedsize_kb, 1, NULL)
 OVER(ORDER BY tmp.rtime)) AS DIFF_KB from tmp, (select max(rtime) rtime from tmp group by substr(rtime, 1, 10)) t2
 where t2.rtime = tmp.rtime;
​
--含undo和temp
with tmp as (
select min(rtime) rtime, sum(tablespace_usedsize_kb) tablespace_usedsize_kb, sum(tablespace_size_kb) tablespace_size_kb 
from (select rtime, e.tablespace_id, (e.tablespace_usedsize) * (f.block_size) / 1024 tablespace_usedsize_kb, 
(e.tablespace_size) * (f.block_size) / 1024 tablespace_size_kb from dba_hist_tbspc_space_usage e, dba_tablespaces f, v$tablespace g 
where e.tablespace_id = g.TS# and f.tablespace_name = g.NAME) group by rtime) 
select tmp.rtime, tablespace_usedsize_kb, tablespace_size_kb, (tablespace_usedsize_kb-LAG(tablespace_usedsize_kb, 1, NULL)
OVER(ORDER BY tmp.rtime)) AS DIFF_KB from tmp, (select min(rtime) rtime from tmp group by substr(rtime, 1, 10)) t2 
where t2.rtime = tmp.rtime
一文看懂Oracle查询表空间的每日增长量和历史情况统计

 


一文看懂Oracle查询表空间的每日增长量和历史情况统计

 


列出相关段对象在 快照时间内的使用空间的历史变化信息

select obj.owner,
 obj.object_name,
 to_char(sn.BEGIN_INTERVAL_TIME, 'RRRR-MON-DD') start_day,
 sum(a.db_block_changes_delta) block_increase
 from dba_hist_seg_stat a, dba_hist_snapshot sn, dba_objects obj
 where sn.snap_id = a.snap_id
 and obj.object_id = a.obj#
 and obj.owner not in ('SYS', 'SYSTEM')
 and end_interval_time between to_timestamp('01-OCT-2019', 'DD-MON-RRRR') and
 to_timestamp('09-OCT-2019', 'DD-MON-RRRR')
 group by obj.owner,
 obj.object_name,
 to_char(sn.BEGIN_INTERVAL_TIME, 'RRRR-MON-DD')
 order by obj.owner, obj.object_name;
一文看懂Oracle查询表空间的每日增长量和历史情况统计
声明:本站部分内容来自互联网,如有版权侵犯或其他问题请与我们联系,我们将立即删除或处理。
▍相关推荐
更多资讯 >>>