Last active
October 6, 2015 13:48
-
-
Save thomasbilk/3002419 to your computer and use it in GitHub Desktop.
Size of all Tables in a Database
This file contains hidden or bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
-- PostgreSQL | |
SELECT | |
schemaname, | |
tablename, | |
pg_size_pretty(size) AS size_pretty, | |
pg_size_pretty(total_size) AS total_size_pretty | |
FROM ( | |
SELECT *, | |
pg_relation_size(schemaname||'.'||tablename) AS size, | |
pg_total_relation_size(schemaname||'.'||tablename) AS total_size | |
FROM | |
pg_tables | |
WHERE schemaname = 'public' | |
) AS TABLES | |
ORDER BY total_size DESC; | |
-- MS SQL Server | |
SELECT | |
t.NAME AS TableName, | |
s.Name AS SchemaName, | |
p.rows AS RowCounts, | |
SUM(a.total_pages) * 8 AS TotalSpaceKB, | |
SUM(a.used_pages) * 8 AS UsedSpaceKB, | |
(SUM(a.total_pages) - SUM(a.used_pages)) * 8 AS UnusedSpaceKB | |
FROM | |
sys.tables t | |
INNER JOIN | |
sys.indexes i ON t.OBJECT_ID = i.object_id | |
INNER JOIN | |
sys.partitions p ON i.object_id = p.OBJECT_ID AND i.index_id = p.index_id | |
INNER JOIN | |
sys.allocation_units a ON p.partition_id = a.container_id | |
LEFT OUTER JOIN | |
sys.schemas s ON t.schema_id = s.schema_id | |
WHERE | |
t.NAME NOT LIKE 'dt%' | |
AND t.is_ms_shipped = 0 | |
AND i.OBJECT_ID > 255 | |
GROUP BY | |
t.Name, s.Name, p.Rows | |
ORDER BY | |
TotalSpaceKB DESC | |
-- MySQL / MariaDB | |
SELECT table_name AS "Tables", | |
round(((data_length + index_length) / 1024 / 1024), 2) "Size in MB" | |
FROM information_schema.TABLES | |
WHERE table_schema = "$DB_NAME" -- <-- change this to database name | |
ORDER BY (data_length + index_length) DESC; | |
Sign up for free
to join this conversation on GitHub.
Already have an account?
Sign in to comment