-- ===========================================================================
-- Oracle PDB Database Growth Analysis Script
-- Author: <Your Name>
-- Description: Tracks DB, Tablespace, and Segment growth over N days
-- Excludes SYSTEM, SYSAUX, UNDO, TEMP, SYS objects
-- Run inside a PDB as DBA
-- ===========================================================================
SET LINESIZE 200
SET PAGESIZE 100
SET VERIFY OFF
SET FEEDBACK ON
SET TRIMSPOOL ON
-- Prompt for number of days
ACCEPT num_days NUMBER PROMPT 'Enter number of days to analyze growth: '
-- Spool file with timestamp
COLUMN spool_time NEW_VALUE SPOOLNAME
SELECT TO_CHAR(SYSDATE, 'YYYYMMDD_HH24MISS') AS spool_time FROM dual;
SPOOL pdb_growth_report_&&spoolname..log
PROMPT
PROMPT =====================================================
PROMPT SECTION 1: TOTAL DATABASE GROWTH OVER &num_days DAYS
PROMPT =====================================================
COLUMN begin_time FORMAT A30
COLUMN end_time FORMAT A30
COLUMN db_size_mb FORMAT 999,999,999
COLUMN growth_mb FORMAT 999,999,999
SELECT
TO_CHAR(s1.begin_interval_time, 'YYYY-MM-DD HH24:MI:SS') AS begin_time,
TO_CHAR(s2.end_interval_time, 'YYYY-MM-DD HH24:MI:SS') AS end_time,
ROUND((s2.value - s1.value)/1024/1024) AS growth_mb,
ROUND(s2.value/1024/1024) AS db_size_mb
FROM
dba_hist_snapshot s1
JOIN
dba_hist_sysstat stat1
ON s1.snap_id = stat1.snap_id AND s1.dbid = stat1.dbid AND s1.instance_number = stat1.instance_number
JOIN
dba_hist_snapshot s2
ON s2.snap_id = s1.snap_id + 1 AND s2.dbid = s1.dbid AND s2.instance_number = s1.instance_number
JOIN
dba_hist_sysstat stat2
ON s2.snap_id = stat2.snap_id AND stat1.stat_id = stat2.stat_id
WHERE
stat1.stat_name = 'db_block_changes'
AND s1.begin_interval_time BETWEEN SYSDATE - &num_days AND SYSDATE
AND ROWNUM = 1;
PROMPT
PROMPT ===============================================================
PROMPT SECTION 2: TABLESPACE-WISE GROWTH (Excludes SYSTEM/UNDO/TEMP)
PROMPT ===============================================================
COLUMN begin_time FORMAT A30
COLUMN end_time FORMAT A30
COLUMN tablespace_name FORMAT A30
COLUMN size_mb FORMAT 999,999,999
COLUMN used_mb FORMAT 999,999,999
COLUMN growth_mb FORMAT 999,999,999
SELECT
dt.tablespace_name,
TO_CHAR(s1.begin_interval_time, 'YYYY-MM-DD HH24:MI:SS') AS begin_time,
TO_CHAR(s2.end_interval_time, 'YYYY-MM-DD HH24:MI:SS') AS end_time,
ROUND((e.tablespace_size * bs.block_size)/1024/1024) AS size_mb,
ROUND((e.tablespace_usedsize * bs.block_size)/1024/1024) AS used_mb,
ROUND(((e.tablespace_usedsize - b.tablespace_usedsize) * bs.block_size)/1024/1024) AS growth_mb
FROM
dba_hist_tbspc_space_usage b
JOIN
dba_hist_tbspc_space_usage e
ON b.tablespace_id = e.tablespace_id
JOIN
dba_hist_snapshot s1
ON b.snap_id = s1.snap_id AND b.dbid = s1.dbid AND b.instance_number = s1.instance_number
JOIN
dba_hist_snapshot s2
ON e.snap_id = s2.snap_id AND e.dbid = s2.dbid AND e.instance_number = s2.instance_number
JOIN
dba_tablespaces dt
ON b.tablespace_id = dt.ts#
JOIN
v$tablespace bs
ON bs.name = dt.tablespace_name
WHERE
s1.begin_interval_time BETWEEN SYSDATE - &num_days AND SYSDATE
AND b.snap_id < e.snap_id
AND dt.tablespace_name NOT IN ('SYSTEM', 'SYSAUX')
AND dt.tablespace_name NOT LIKE 'UNDO%'
AND dt.tablespace_name NOT LIKE 'TEMP%'
AND ROWNUM = 1
ORDER BY
dt.tablespace_name;
PROMPT
PROMPT ==========================================================
PROMPT SECTION 3: SEGMENT-WISE GROWTH (Excludes SYS/SYSTEM objects)
PROMPT ==========================================================
COLUMN owner FORMAT A20
COLUMN segment_name FORMAT A30
COLUMN segment_type FORMAT A15
COLUMN tablespace_name FORMAT A20
COLUMN growth_mb FORMAT 999,999,999.99
SELECT
obj.owner,
obj.segment_name,
obj.segment_type,
obj.tablespace_name,
ROUND(SUM(s.bytes_delta)/1024/1024, 2) AS growth_mb
FROM
dba_hist_seg_stat s
JOIN
dba_hist_seg_stat_obj obj
ON s.obj# = obj.obj#
JOIN
dba_hist_snapshot snap
ON s.snap_id = snap.snap_id AND s.dbid = snap.dbid AND s.instance_number = snap.instance_number
WHERE
snap.begin_interval_time BETWEEN SYSDATE - &num_days AND SYSDATE
AND obj.owner NOT IN ('SYS','SYSTEM')
AND obj.tablespace_name NOT IN ('SYSTEM','SYSAUX')
AND obj.tablespace_name NOT LIKE 'UNDO%'
AND obj.tablespace_name NOT LIKE 'TEMP%'
GROUP BY
obj.owner, obj.segment_name, obj.segment_type, obj.tablespace_name
HAVING
SUM(s.bytes_delta) > 0
ORDER BY
growth_mb DESC;
SPOOL OFF