-- ====================================================================================
-- Script Name : pdb_db_growth_by_days.sql
-- Purpose : Analyze Database Growth over Last N Days (User-Driven, PDB-aware)
-- Author : ChatGPT for Raunak
-- Requirements: Run from SQL*Plus inside PDB with access to DBA_HIST_* views
-- ====================================================================================
SET ECHO OFF
SET LINESIZE 200
SET PAGESIZE 100
SET FEEDBACK OFF
SET VERIFY OFF
SET TRIMSPOOL ON
-- === Accept user input for days ===
ACCEPT v_days NUMBER PROMPT 'Enter number of days to analyze growth (e.g., 30): '
-- === Generate spool file with timestamp ===
COLUMN spool_file_name NEW_VALUE spool_file
SELECT 'db_growth_' || TO_CHAR(SYSDATE, 'YYYYMMDD_HH24MISS') || '.lst' AS spool_file_name FROM dual;
SPOOL &spool_file
-- === Column formatting ===
COLUMN START_TIME FORMAT A20
COLUMN END_TIME FORMAT A20
COLUMN TABLESPACE_NAME FORMAT A30
COLUMN GROWTH_GB FORMAT 9999.99
COLUMN OWNER FORMAT A20
COLUMN OBJECT_NAME FORMAT A30
COLUMN OBJECT_TYPE FORMAT A15
COLUMN GROWTH_MB FORMAT 999,999.99
COLUMN FIRST_SEEN FORMAT A20
COLUMN LAST_SEEN FORMAT A20
COLUMN INSTANCE_NUMBER FORMAT 999
PROMPT ============================================================================
PROMPT [1] Total Database Growth Over Last &v_days Days
PROMPT ============================================================================
SELECT
MIN(s.begin_interval_time) AS START_TIME,
MAX(s.end_interval_time) AS END_TIME,
ROUND(MAX(used_gb) - MIN(used_gb), 2) AS TOTAL_DB_GROWTH_GB
FROM (
SELECT
ss.snap_id,
SUM(tsu.tablespace_usedsize * ts.block_size) / 1024 / 1024 / 1024 AS used_gb
FROM
dba_hist_tbspc_space_usage tsu
JOIN dba_hist_snapshot ss ON tsu.snap_id = ss.snap_id AND tsu.dbid = ss.dbid
JOIN dba_tablespaces ts ON ts.ts# = tsu.tablespace_id
WHERE
ss.begin_interval_time >= SYSDATE - &v_days
GROUP BY
ss.snap_id
) growth
JOIN dba_hist_snapshot s ON s.snap_id = growth.snap_id;
PROMPT ============================================================================
PROMPT [2] Tablespace-wise Growth Over Last &v_days Days
PROMPT ============================================================================
SELECT
ts.name AS TABLESPACE_NAME,
MIN(ss.begin_interval_time) AS START_TIME,
MAX(ss.end_interval_time) AS END_TIME,
ROUND((MAX(tsu.tablespace_usedsize) - MIN(tsu.tablespace_usedsize)) * ts.block_size / 1024 / 1024 / 1024, 2) AS GROWTH_GB
FROM
dba_hist_tbspc_space_usage tsu
JOIN dba_hist_snapshot ss ON tsu.snap_id = ss.snap_id AND tsu.dbid = ss.dbid
JOIN dba_tablespaces ts ON ts.ts# = tsu.tablespace_id
WHERE
ss.begin_interval_time >= SYSDATE - &v_days
GROUP BY
ts.name
HAVING
ROUND((MAX(tsu.tablespace_usedsize) - MIN(tsu.tablespace_usedsize)) * ts.block_size / 1024 / 1024 / 1024, 2) > 0
ORDER BY
GROWTH_GB DESC;
PROMPT ============================================================================
PROMPT [3] Top Growing Segments Over Last &v_days Days
PROMPT ============================================================================
SELECT
obj.owner,
obj.object_name,
obj.subobject_name,
obj.object_type,
ROUND(SUM(sss.space_used_delta) * 8 / 1024, 2) AS GROWTH_MB,
MIN(s.begin_interval_time) AS FIRST_SEEN,
MAX(s.end_interval_time) AS LAST_SEEN,
MAX(s.instance_number) AS INSTANCE_NUMBER
FROM
dba_hist_seg_stat sss
JOIN dba_hist_seg_stat_obj obj ON sss.obj# = obj.obj#
JOIN dba_hist_snapshot s ON s.snap_id = sss.snap_id AND s.dbid = sss.dbid
WHERE
s.begin_interval_time >= SYSDATE - &v_days
GROUP BY
obj.owner, obj.object_name, obj.subobject_name, obj.object_type
HAVING
SUM(sss.space_used_delta) > 0
ORDER BY
GROWTH_MB DESC
FETCH FIRST 15 ROWS ONLY;
PROMPT ============================================================================
PROMPT Done. Report saved to &spool_file
PROMPT ============================================================================
SPOOL OFF