diff --git a/README.md b/README.md index e0c7acc..152593b 100644 --- a/README.md +++ b/README.md @@ -275,7 +275,7 @@ Columns: * size - index size. -Show indexes with following conditions: (idx_scan / write_activity) < 0.01 и write_activity > 10000. +Show indexes with following conditions: (idx_scan / write_activity) < 0.01 and write_activity > 10000. ### master_wal_position.sql diff --git a/sql/index_bloat.sql b/sql/index_bloat.sql new file mode 100644 index 0000000..a10eded --- /dev/null +++ b/sql/index_bloat.sql @@ -0,0 +1,29 @@ +--pgstattuple extension required +--WARNING: without index name/mask query will read all available indexes which could cause I/O spikes +with indexes as ( + select * from pg_stat_user_indexes +) +select schemaname, +table_name, +pg_size_pretty(table_size) as table_size, +index_name, +pg_size_pretty(index_size) as index_size, +idx_scan as index_scans, +round((free_space*100/index_size)::numeric, 1) as waste_percent, +pg_size_pretty(free_space) as waste +from ( + select schemaname, p.relname as table_name, indexrelname as index_name, + (select (case when avg_leaf_density = 'NaN' then 0 + else greatest(ceil(index_size * (1 - avg_leaf_density / (coalesce((SELECT (regexp_matches(reloptions::text, E'.*fillfactor=(\\d+).*'))[1]),'90')::real)))::bigint, 0) end) + from pgstatindex(schemaname || '.' || p.indexrelid::regclass::text) + ) as free_space, + pg_relation_size(p.indexrelid) as index_size, + pg_relation_size(p.relid) as table_size, + idx_scan + from indexes p + join pg_class c on p.indexrelid = c.oid + where pg_get_indexdef(p.indexrelid) like '%USING btree%' and + --put your index name/mask here + indexrelname ~ '' +) t +order by free_space desc; \ No newline at end of file diff --git a/sql/table_bloat.sql b/sql/table_bloat.sql new file mode 100644 index 0000000..9ec7ad9 --- /dev/null +++ b/sql/table_bloat.sql @@ -0,0 +1,26 @@ +--pgstattuple extension required +--WARNING: without table name/mask query will read all available tables which could cause I/O spikes +select nspname, +relname, +pg_size_pretty(relation_size + toast_relation_size) as total_size, +pg_size_pretty(toast_relation_size) as toast_size, +round(((relation_size - (relation_size - free_space)*100/fillfactor)/greatest(relation_size, 1))::numeric, 1) table_waste_percent, +pg_size_pretty((relation_size - (relation_size - free_space)*100/fillfactor)::bigint) table_waste, +round(((toast_free_space + relation_size - (relation_size - free_space)*100/fillfactor)*100/greatest(relation_size + toast_relation_size, 1))::numeric, 1) total_waste_percent, +pg_size_pretty((toast_free_space + relation_size - (relation_size - free_space)*100/fillfactor)::bigint) total_waste +from ( + select nspname, relname, + (select free_space from pgstattuple(c.oid)) as free_space, + pg_relation_size(c.oid) as relation_size, + (case when reltoastrelid = 0 then 0 else (select free_space from pgstattuple(c.reltoastrelid)) end) as toast_free_space, + coalesce(pg_relation_size(c.reltoastrelid), 0) as toast_relation_size, + coalesce((SELECT (regexp_matches(reloptions::text, E'.*fillfactor=(\\d+).*'))[1]),'100')::real AS fillfactor + from pg_class c + left join pg_namespace n on (n.oid = c.relnamespace) + where nspname not in ('pg_catalog', 'information_schema') + and nspname !~ '^pg_toast' and relkind = 'r' + --put your table name/mask here + and relname ~ '' +) t +order by (toast_free_space + relation_size - (relation_size - free_space)*100/fillfactor) desc +limit 20; \ No newline at end of file diff --git a/sql/top_databases.sql b/sql/top_databases.sql new file mode 100644 index 0000000..b31d04e --- /dev/null +++ b/sql/top_databases.sql @@ -0,0 +1,12 @@ +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 +LIMIT 20; \ No newline at end of file diff --git a/sql/top_tables.sql b/sql/top_tables.sql new file mode 100644 index 0000000..9ca916c --- /dev/null +++ b/sql/top_tables.sql @@ -0,0 +1,14 @@ +SELECT + nspname, + relname, + relkind as "type", + pg_size_pretty(pg_table_size(C.oid)) AS size, + pg_size_pretty(pg_indexes_size(C.oid)) AS idxsize, + pg_size_pretty(pg_total_relation_size(C.oid)) as "total" +FROM pg_class C +LEFT JOIN pg_namespace N ON (N.oid = C.relnamespace) +WHERE nspname NOT IN ('pg_catalog', 'information_schema') AND + nspname !~ '^pg_toast' AND + relkind IN ('r','i') +ORDER BY pg_total_relation_size(C.oid) DESC +LIMIT 20; \ No newline at end of file