合 Oracle查询表空间或数据库的增长量
Tags: Oracle脚本DBA脚本表空间大小每天增量表空间每日增长量数据增长量
简介
在Oracle数据库中,我们有时候在分析一些问题时,需要了解哪一些表空间的数据增长了。我们需要快速定位数据量增长较快的用户表空间,或者在哪一些时间段表空间数据量突然飚增了。
10g或11g
1 2 3 4 5 6 7 8 9 10 11 12 13 14 15 16 17 18 19 20 21 22 | 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; |
或:
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 39 | set linesize 860; set pagesize 120; alter session set nls_date_format='yyyy-mm-dd hh24:mi:ss'; col tb_name for a16; col ts_mb for 999,999,999.90 col max_mb for 999,999,999.90 col used_mb for 999,999,999.90 col last_mb for 999,999,999.90 col incr for 999,999.90 select * from ( select v.name tb_name ,v.ts# ,s.instance_number ,h.tablespace_size * round(p.value/1024/1024,2) ts_mb ,h.tablespace_maxsize * round(p.value/1024/1024,2) max_mb ,h.tablespace_usedsize * round(p.value/1024/1024,2) used_mb ,to_date(h.rtime, 'MM/DD/YYYY HH24:MI:SS') resize_time ,lag(h.tablespace_usedsize * p.value/1024/1024, 1, h.tablespace_usedsize * p.value/1024/1024) over (partition by v.ts# order by h.snap_id) last_mb ,(h.tablespace_usedsize * p.value/1024/1024) - lag(h.tablespace_usedsize * p.value/1024/1024, 1, h.tablespace_usedsize * p.value/1024/1024) over (partition by v.ts# order by h.snap_id) incr from dba_hist_tbspc_space_usage h , dba_hist_snapshot s , v$tablespace v , dba_tablespaces t , v$parameter p where h.tablespace_id = v.ts# and v.name = t.tablespace_name and t.contents not in ('UNDO', 'TEMPORARY') and p.name = 'db_block_size' and h.snap_id = s.snap_id /* For a specific time */ and s.begin_interval_time > sysdate - 7 -- and v.name =upper('&tablespace_name') order by v.name, h.snap_id asc) where incr > 0; |
12c或更高版本
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 | 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; |
或:
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 39 40 41 42 43 44 45 | -- 注意:此脚本要在CDB下执行才能查看所有PDB的表空间信息。如果在指定的PDB下执行的,只能查看当前PDB的表空间增长信息 set linesize 860; set pagesize 120; alter session set nls_date_format='yyyy-mm-dd hh24:mi:ss'; col con_id for 999 col name for a16 col ts# for 999 col ts_mb for 999,999,999.90 col max_mb for 999,999,999.90 col used_mb for 999,999,999.90 col last_mb for 999,999,999.90 col incr for 999,999.90 select * from ( select v.con_id ,v.name ,v.ts# ,s.instance_number ,h.tablespace_size * p.value/1024/1024 ts_mb ,h.tablespace_maxsize * p.value/1024/1024 max_mb ,h.tablespace_usedsize * p.value/1024/1024 used_mb ,to_date(h.rtime, 'MM/DD/YYYY HH24:MI:SS') resize_time ,lag(h.tablespace_usedsize * p.value/1024/1024, 1, h.tablespace_usedsize * p.value/1024/1024) over (partition by v.ts# order by h.snap_id) last_mb ,(h.tablespace_usedsize * p.value/1024/1024) - lag(h.tablespace_usedsize * p.value/1024/1024, 1, h.tablespace_usedsize * p.value/1024/1024) over (partition by v.con_id, v.ts# order by h.snap_id) incr from cdb_hist_tbspc_space_usage h , cdb_hist_snapshot s , v$tablespace v , cdb_tablespaces t , v$parameter p where h.tablespace_id = v.ts# and h.con_id = v.con_id and h.con_id = t.con_id and v.name = t.tablespace_name and v.con_id = t.con_id and t.contents not in ('UNDO', 'TEMPORARY') and p.name = 'db_block_size' and h.snap_id = s.snap_id /* For a specific time */ and s.begin_interval_time > sysdate - 7 -- and v.name =upper('&tablespace_name') order by v.con_id, v.name, h.snap_id asc) where incr > 0; |
如何估算oracle数据库对象历史增长情况
最近七天数据库的增长情况,这个只是一个估算值。
1 2 3 4 5 6 7 8 | 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; |
其它SQL
SYSTEM表空间增量量
1 2 3 4 5 6 7 8 9 10 11 12 13 14 15 16 17 18 19 | select u.snap_id, to_char(s.begin_interval_time, 'yyyy-mm-dd hh24') begin_time, to_char(s.end_interval_time, 'yyyy-mm-dd hh24') end_time, t.name, round(u.tablespace_size * ts.block_size / 1024 / 1024, 2) ts_size_mb, round(u.tablespace_usedsize * ts.block_size / 1024 / 1024, 2) ts_used_mb, round((u.tablespace_size - u.tablespace_usedsize) * ts.block_size / 1024 / 1024, 2) ts_free_mb, round(u.tablespace_usedsize / u.tablespace_size * 100, 2) pct_used from dba_hist_tbspc_space_usage u, v$tablespace t, dba_hist_snapshot s, dba_tablespaces ts where u.tablespace_id = t.ts# and u.snap_id = s.snap_id and t.name = ts.tablespace_name and s.instance_number = 1 and t.name = 'SYSTEM' and s.end_interval_time > sysdate - 7 order by snap_id desc; |
不含undo和temp
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 | 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
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 | 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; |
列出相关段对象在 快照时间内的使用空间的历史变化信息
1 2 3 4 5 6 7 8 9 10 11 12 13 14 15 16 17 18 19 20 | column owner format a16 column object_name format a36 column start_day format a11 column block_increase format 9999999999 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('17-FEB-2014','DD-MON-RRRR') and to_timestamp('25-FEB-2014','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 ; |