Last active
November 1, 2018 18:49
-
-
Save ondrej-kvasnovsky/fdf864c5b9207a2963a946dff8028ae0 to your computer and use it in GitHub Desktop.
Find out biggest databases and tables in Postgres
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
-- find biggest database | |
SELECT *, pg_size_pretty(total_bytes) AS total | |
, pg_size_pretty(index_bytes) AS INDEX | |
, pg_size_pretty(toast_bytes) AS toast | |
, pg_size_pretty(table_bytes) AS TABLE | |
FROM ( | |
SELECT *, total_bytes-index_bytes-COALESCE(toast_bytes,0) AS table_bytes FROM ( | |
SELECT c.oid,nspname AS table_schema, relname AS TABLE_NAME | |
, c.reltuples AS row_estimate | |
, pg_total_relation_size(c.oid) AS total_bytes | |
, pg_indexes_size(c.oid) AS index_bytes | |
, pg_total_relation_size(reltoastrelid) AS toast_bytes | |
FROM pg_class c | |
LEFT JOIN pg_namespace n ON n.oid = c.relnamespace | |
WHERE relkind = 'r' | |
) a | |
) a; | |
-- get size of a specific database | |
SELECT pg_size_pretty(pg_database_size('mydatabase')); | |
-- find biggest tables | |
SELECT d.datname AS Name, pg_catalog.pg_get_userbyid(d.datdba) AS Owner, | |
CASE WHEN pg_catalog.has_database_privilege(d.datname, 'CONNECT') | |
THEN pg_catalog.pg_size_pretty(pg_catalog.pg_database_size(d.datname)) | |
ELSE 'No Access' | |
END AS SIZE | |
FROM pg_catalog.pg_database d | |
ORDER BY | |
CASE WHEN pg_catalog.has_database_privilege(d.datname, 'CONNECT') | |
THEN pg_catalog.pg_database_size(d.datname) | |
ELSE NULL | |
END DESC -- nulls first | |
LIMIT 20; | |
SELECT nspname || '.' || relname AS "relation", | |
pg_size_pretty(pg_relation_size(C.oid)) AS "size" | |
FROM pg_class C | |
LEFT JOIN pg_namespace N ON (N.oid = C.relnamespace) | |
WHERE nspname NOT IN ('pg_catalog', 'information_schema') | |
ORDER BY pg_relation_size(C.oid) DESC | |
LIMIT 20; | |
SELECT nspname || '.' || relname AS "relation", | |
pg_size_pretty(pg_total_relation_size(C.oid)) AS "total_size" | |
FROM pg_class C | |
LEFT JOIN pg_namespace N ON (N.oid = C.relnamespace) | |
WHERE nspname NOT IN ('pg_catalog', 'information_schema') | |
AND C.relkind <> 'i' | |
AND nspname !~ '^pg_toast' | |
ORDER BY pg_total_relation_size(C.oid) DESC | |
LIMIT 20; | |
-- check size of replication slots | |
SELECT * FROM pg_replication_slots; | |
SELECT | |
slot_name, | |
database, | |
active, | |
pg_xlog_location_diff(pg_current_xlog_insert_location(), restart_lsn) AS retained_bytes | |
FROM pg_replication_slots ; | |
SELECT pg_drop_replication_slot('name_of_slot_to_remove'); |
Sign up for free
to join this conversation on GitHub.
Already have an account?
Sign in to comment