-
Notifications
You must be signed in to change notification settings - Fork 113
/
oracle_table_space.sql
53 lines (51 loc) · 1.81 KB
/
oracle_table_space.sql
1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18
19
20
21
22
23
24
25
26
27
28
29
30
31
32
33
34
35
36
37
38
39
40
41
42
43
44
45
46
47
48
49
50
51
52
53
--
-- Author: Hari Sekhon
-- Date: 2024-10-11 03:24:48 +0300 (Fri, 11 Oct 2024)
--
-- vim:ts=4:sts=4:sw=4:et:filetype=sql
--
-- https///github.com/HariSekhon/SQL-scripts
--
-- License: see accompanying Hari Sekhon LICENSE file
--
-- If you're using my code you're welcome to connect with me on LinkedIn and optionally send me feedback to help steer this or other code I publish
--
-- https://www.linkedin.com/in/HariSekhon
--
-- Oracle - Show Tables' Space Used vs Free and Free Percentage
--
-- where the tables are over 20% utilized
--
-- Calculations assume an 8KB block size, which you should verify like this:
--
-- SELECT value FROM v$parameter WHERE name = 'db_block_size';
--
-- Tested on Oracle 19c
SELECT
owner,
table_name,
-- each block is 8KB, multiply it to GB, round to two decimal places
ROUND(blocks * 8 / 1024 / 1024, 2) AS total_gb,
-- estimate data size from rows vs average row size, round to two decimal places
ROUND(num_rows * avg_row_len / 1024 / 1024 / 1024, 2) AS actual_data_gb,
-- estimate free space by subtracting the two above calculations
ROUND((blocks * 8 / 1024 / 1024) - (num_rows * avg_row_len / 1024 / 1024 / 1024), 2) AS free_space_gb,
-- calculate free space percentage from the above three calculations
ROUND(
( (blocks * 8 / 1024 / 1024) - (num_rows * avg_row_len / 1024 / 1024 / 1024) ) /
(blocks * 8 / 1024 / 1024) * 100, 2) AS free_space_pct
FROM
dba_tables
WHERE
blocks > 0
AND
num_rows > 0
AND
((blocks * 8 / 1024 / 1024) - (num_rows * avg_row_len / 1024 / 1024 / 1024)) /
(blocks * 8 / 1024 / 1024) > 0.2 -- TUNE: currently only showing tables over 20% utilized
AND
owner NOT IN
('SYS', 'SYSTEM', 'SYSAUX', 'RDSADMIN')
ORDER BY
free_space_gb DESC,
total_gb DESC;