-- ============================================================================

-- Oracle PDB Growth Analysis Script (Final, Verified)

-- Author: <Your Name>

-- Works inside PDB, no SYS-only views, fully accessible

-- ============================================================================


SET LINES 200

SET PAGES 100

SET VERIFY OFF

SET FEEDBACK OFF

SET TRIMSPOOL ON


ACCEPT num_days NUMBER PROMPT 'Enter number of days to analyze growth: '


COLUMN spool_time NEW_VALUE spoolname

SELECT TO_CHAR(SYSDATE, 'YYYYMMDD_HH24MISS') spool_time FROM dual;

SPOOL pdb_growth_report_&&spoolname..log


-- ============================================================================

PROMPT

PROMPT ===========================

PROMPT SECTION 1: TOTAL DB GROWTH

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(MIN(s.begin_interval_time), 'YYYY-MM-DD HH24:MI:SS') AS begin_time,

    TO_CHAR(MAX(s.end_interval_time), 'YYYY-MM-DD HH24:MI:SS')   AS end_time,

    ROUND((MAX(ss.value) - MIN(ss.value))/1024/1024) AS growth_mb,

    ROUND(MAX(ss.value)/1024/1024) AS db_size_mb

FROM

    dba_hist_sysstat ss,

    dba_hist_snapshot s

WHERE

    ss.snap_id = s.snap_id

    AND ss.dbid = s.dbid

    AND ss.stat_name = 'db_block_changes'

    AND s.begin_interval_time BETWEEN SYSDATE - &num_days AND SYSDATE;


-- ============================================================================

PROMPT

PROMPT ================================================

PROMPT SECTION 2: TABLESPACE-WISE GROWTH (no SYSTEM TBS)

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

    u.tablespace_name,

    TO_CHAR(MIN(s.begin_interval_time), 'YYYY-MM-DD HH24:MI:SS') AS begin_time,

    TO_CHAR(MAX(s.end_interval_time), 'YYYY-MM-DD HH24:MI:SS')   AS end_time,

    ROUND(MAX(u.tablespace_size) * dt.block_size/1024/1024) AS size_mb,

    ROUND(MAX(u.tablespace_usedsize) * dt.block_size/1024/1024) AS used_mb,

    ROUND((MAX(u.tablespace_usedsize) - MIN(u.tablespace_usedsize)) * dt.block_size / 1024 / 1024) AS growth_mb

FROM

    dba_hist_tbspc_space_usage u,

    dba_hist_snapshot s,

    dba_tablespaces dt

WHERE

    u.snap_id = s.snap_id

    AND u.dbid = s.dbid

    AND u.tablespace_name = dt.tablespace_name

    AND s.begin_interval_time BETWEEN SYSDATE - &num_days AND SYSDATE

    AND dt.tablespace_name NOT IN ('SYSTEM', 'SYSAUX')

    AND dt.tablespace_name NOT LIKE 'UNDO%'

    AND dt.tablespace_name NOT LIKE 'TEMP%'

GROUP BY

    u.tablespace_name, dt.block_size

ORDER BY

    growth_mb DESC;


-- ============================================================================

PROMPT

PROMPT ============================================================

PROMPT SECTION 3: SEGMENT-WISE GROWTH (Excludes SYS/SYSTEM objects)

PROMPT ============================================================


COLUMN owner FORMAT A20

COLUMN segment_name FORMAT A30

COLUMN tablespace_name FORMAT A20

COLUMN growth_mb FORMAT 999,999,999.99


WITH segment_usage AS (

    SELECT

        s.snap_id,

        o.owner,

        o.segment_name,

        o.tablespace_name,

        SUM(s.bytes) AS total_bytes

    FROM

        dba_hist_seg_stat s

    JOIN

        dba_hist_seg_stat_obj o ON s.obj# = o.obj#

    JOIN

        dba_hist_snapshot snap ON s.snap_id = snap.snap_id AND s.dbid = snap.dbid

    WHERE

        snap.begin_interval_time BETWEEN SYSDATE - &num_days AND SYSDATE

        AND o.owner NOT IN ('SYS','SYSTEM')

        AND o.tablespace_name NOT IN ('SYSTEM','SYSAUX')

        AND o.tablespace_name NOT LIKE 'UNDO%'

        AND o.tablespace_name NOT LIKE 'TEMP%'

    GROUP BY

        s.snap_id, o.owner, o.segment_name, o.tablespace_name

),

first_last AS (

    SELECT owner, segment_name, tablespace_name,

           MIN(total_bytes) AS min_bytes,

           MAX(total_bytes) AS max_bytes

    FROM segment_usage

    GROUP BY owner, segment_name, tablespace_name

)

SELECT

    owner,

    segment_name,

    tablespace_name,

    ROUND((max_bytes - min_bytes)/1024/1024, 2) AS growth_mb

FROM

    first_last

WHERE

    (max_bytes - min_bytes) > 0

ORDER BY

    growth_mb DESC;


SPOOL OFF

Popular posts from this blog