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;
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;
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;
-----最近七天数据库的增长情况,这个只是一个估算值。
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;
查看数据库历史增长情况 此处是通过计算数据库所有表空间的历史增长情况来计算数据库历史情况。
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;
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;
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 ;
统计数据库的规模一般会从两个维度考虑,一个是真实的数据库对象所占的空间,另一个是物理磁盘需要占多少空间。
前者是逻辑对象的数据规模,后者是磁盘上实际的数据文件大小。逻辑对象是存在物理文件中的,文件提前分好了空间,文件内容会等待逻辑对象填满。比如提前分好了一个32GB的表空间,数据没存满前,文件大小不会变,但对象所占的空间是在增长的。
统计数据库数据量大小的 SQL 语句如下:
-- 对象大小
select sum(t.bytes)/1024/1024/1024/1024 TB
from dba_segments t;
-- 数据文件大小
select sum(t.bytes)/1024/1024/1024/1024 TB
from dba_data_files t;
如果需要统计每年的数据库的数据量的增长量,一种笨办法则是每年统计一次,将结果存下来,多年之后再将数据取出来进行分析。Oracle中并不会记录数据增长的历史,唯一一种可以近似得到数据增长历史的地方是v
datafile统计的数据增长量如下:
图片
SQL语句为:
SELECT trunc(t.creation_time, 'yyyy'),
round(SUM(t.bytes) / 1024 / 1024 / 1024 / 1024, 2) tb
FROM v$datafile t
GROUP BY trunc(t.creation_time, 'yyyy')
ORDER BY 1;
这里有一个问题就是如果数据库的生命周期不完整了,比如经历过数据迁移、resetlog 导致归档日志不再连接,此时 v$datafile 中记录的数据文件创建时间已经被重置,之前的历史记录会丢失。此时数据库相当于重生了,之前的数据文件创建时间都被重置为数据库的第一次打开时间。比如上面的记录 2017 年以前的数据文件增长记录都无法考证了,原因是经历过 resetlog 打开数据库。
图片