Skip to Main Content

Breadcrumb

Question and Answer

Chris Saxon

Thanks for the question, brijesh.

Asked: January 14, 2020 - 1:13 pm UTC

Last updated: January 21, 2020 - 12:58 pm UTC

Version: 12.1.0.2

Viewed 10K+ times! This question is

You Asked

Hi,

I need query to find out Database growth. However in google lots of queries are available but not getting exact result. Currently was using below queries, if possible can you explain which query i need to use to get most accurate DB growth result.

*****************************************************************************************************
SELECT TO_CHAR (sp.begin_interval_time,'DD-MM-YYYY') days
, ts.tsname
, max(round((tsu.tablespace_size* dt.block_size )/(1024*1024),2) ) cur_size_MB
, max(round((tsu.tablespace_usedsize* dt.block_size )/(1024*1024),2)) usedsize_MB
FROM DBA_HIST_TBSPC_SPACE_USAGE tsu
, DBA_HIST_TABLESPACE_STAT ts
, DBA_HIST_SNAPSHOT sp
, DBA_TABLESPACES dt
WHERE tsu.tablespace_id= ts.ts#
AND tsu.snap_id = sp.snap_id
AND ts.tsname = dt.tablespace_name
AND ts.tsname NOT IN ('SYSAUX','SYSTEM')
GROUP BY TO_CHAR (sp.begin_interval_time,'DD-MM-YYYY'), ts.tsname
ORDER BY ts.tsname, days;
*********************************************************************************************

select to_char(CREATION_TIME,'RRRR') year, to_char(CREATION_TIME,'MM') month, round(sum(bytes)/1024/1024/1024) GB
from v$datafile
group by to_char(CREATION_TIME,'RRRR'), to_char(CREATION_TIME,'MM')
order by 1, 2;
**********************************************************************************************

Declare
v_BaselineSize number(20);
v_CurrentSize number(20);
v_TotalGrowth number(20);
v_Space number(20);
cursor usageHist is
select a.snap_id,
SNAP_TIME,
sum(TOTAL_SPACE_ALLOCATED_DELTA) over ( order by a.SNAP_ID) ProgSum
from
(select SNAP_ID,
sum(SPACE_ALLOCATED_DELTA) TOTAL_SPACE_ALLOCATED_DELTA
from DBA_HIST_SEG_STAT
group by SNAP_ID
having sum(SPACE_ALLOCATED_TOTAL) <> 0
order by 1 ) a,
(select distinct SNAP_ID,
to_char(END_INTERVAL_TIME,'DD-Mon-YYYY HH24:Mi') SNAP_TIME
from DBA_HIST_SNAPSHOT) b
where a.snap_id=b.snap_id;
Begin
select sum(SPACE_ALLOCATED_DELTA) into v_TotalGrowth from DBA_HIST_SEG_STAT;
select sum(bytes) into v_CurrentSize from dba_segments;
v_BaselineSize := v_CurrentSize - v_TotalGrowth ;

dbms_output.put_line('SNAP_TIME Database Size(MB)');

for row in usageHist loop
v_Space := (v_BaselineSize + row.ProgSum)/(1024*1024);
dbms_output.put_line(row.SNAP_TIME || ' ' || to_char(v_Space) );
end loop;
end;


Thanks,
Brijesh

and Connor said...

The second one is not useful - it does not give a true trend information.

The first and third ones does similar things, just via different dictionary views.

But being a fan of simple SQL, I prefer the first, and you can easily tailor that to be more granular (eg, down the the snapshot time interval) or less granular (but removing the tablespace grouping).

Rating

  (1 rating)

Is this answer out of date? If it is, please let us know via a Comment

Comments

A reader, January 21, 2020 - 9:05 am UTC

Thank you !!!
Chris Saxon
January 21, 2020 - 12:58 pm UTC

You're welcome

More to Explore

Administration

Need more information on Administration? Check out the Administrators guide for the Oracle Database