4 .TABLESPACE MONITORING

1. Get the allocated size of a tablespace:


select tablespace_name,sum(bytes/1024/1024/1024) from dba_data_files where  tablespace_name='USERS';

2. Get free space in a tablespace:


select tablespace_name,sum(bytes/1024/1024/1024) from dba_free_space where  tablespace_name='USERS';

3. Script to Monitor tablespace Usage:


set feedback off 
set pagesize 70; 
set linesize 2000 
set head on 
COLUMN Tablespace format a25 heading 'Tablespace Name' 
COLUMN autoextensible format a11 heading 'AutoExtend' 
COLUMN files_in_tablespace format 999 heading 'Files' 
COLUMN total_tablespace_space format 99999999 heading 'TotalSpace' 
COLUMN total_used_space format 99999999 heading 'UsedSpace' 
COLUMN total_tablespace_free_space format 99999999 heading 'FreeSpace' 
COLUMN total_used_pct format 9999 heading '%Used' 
COLUMN total_free_pct format 9999 heading '%Free' 
COLUMN max_size_of_tablespace format 99999999 heading 'ExtendUpto' 
COLUM total_auto_used_pct format 999.99 heading 'Max%Used' 
COLUMN total_auto_free_pct format 999.99 heading 'Max%Free' 
WITH tbs_auto AS 
(SELECT DISTINCT tablespace_name, autoextensible 
FROM dba_data_files 
WHERE autoextensible = 'YES'), 
files AS 
(SELECT tablespace_name, COUNT (*) tbs_files, 
SUM (BYTES/1024/1024) total_tbs_bytes 
FROM dba_data_files 
GROUP BY tablespace_name), 
fragments AS 
(SELECT tablespace_name, COUNT (*) tbs_fragments, 
SUM (BYTES)/1024/1024 total_tbs_free_bytes, 
MAX (BYTES)/1024/1024 max_free_chunk_bytes 
FROM dba_free_space 
GROUP BY tablespace_name), 
AUTOEXTEND AS 
(SELECT tablespace_name, SUM (size_to_grow) total_growth_tbs 
FROM (SELECT tablespace_name, SUM (maxbytes)/1024/1024 size_to_grow 
FROM dba_data_files 
WHERE autoextensible = 'YES' 
GROUP BY tablespace_name 
UNION 
SELECT tablespace_name, SUM (BYTES)/1024/1024 size_to_grow 
FROM dba_data_files 
WHERE autoextensible = 'NO' 
GROUP BY tablespace_name) 
GROUP BY tablespace_name) 
SELECT c.instance_name,a.tablespace_name Tablespace, 
CASE tbs_auto.autoextensible 
WHEN 'YES' 
THEN 'YES' 
ELSE 'NO' 
END AS autoextensible, 
files.tbs_files files_in_tablespace, 
files.total_tbs_bytes total_tablespace_space, 
(files.total_tbs_bytes - fragments.total_tbs_free_bytes 
) total_used_space, 
fragments.total_tbs_free_bytes total_tablespace_free_space, 
round(( ( (files.total_tbs_bytes - fragments.total_tbs_free_bytes) 
/ files.total_tbs_bytes 
) 
* 100 
)) total_used_pct, 
round(((fragments.total_tbs_free_bytes / files.total_tbs_bytes) * 100 
)) total_free_pct 
FROM dba_tablespaces a,v$instance c , files, fragments, AUTOEXTEND, tbs_auto 
WHERE a.tablespace_name = files.tablespace_name 
AND a.tablespace_name = fragments.tablespace_name 
AND a.tablespace_name = AUTOEXTEND.tablespace_name 
AND a.tablespace_name = tbs_auto.tablespace_name(+) 
order by total_free_pct;

4. Monitor temp tablespace usage:


select a.tablespace_name tablespace, 
d.TEMP_TOTAL_MB, 
sum (a.used_blocks * d.block_size) / 1024 / 1024 TEMP_USED_MB, 
d.TEMP_TOTAL_MB - sum (a.used_blocks * d.block_size) / 1024 / 1024 TEMP_FREE_MB 
from v$sort_segment a, 
( 
select b.name, c.block_size, sum (c.bytes) / 1024 / 1024 TEMP_TOTAL_MB 
from v$tablespace b, v$tempfile c 
where b.ts#= c.ts# 
group by b.name, c.block_size 
) d 
where a.tablespace_name = d.name 
group by a.tablespace_name, d.TEMP_TOTAL_MB;

5. Undo tablespace usage:/


select a.tablespace_name, SIZEMB, USAGEMB, (SIZEMB - USAGEMB) FREEMB 
from (select sum(bytes) / 1024 / 1024 SIZEMB, b.tablespace_name 
from dba_data_files a, dba_tablespaces b 
where a.tablespace_name = b.tablespace_name 
and b.contents = 'UNDO' 
group by b.tablespace_name) a, 
(select c.tablespace_name, sum(bytes) / 1024 / 1024 USAGEMB 
from DBA_UNDO_EXTENTS c 
where status ❮❯ 'EXPIRED' 
group by c.tablespace_name) b 
where a.tablespace_name = b.tablespace_name;