Created
December 21, 2020 15:25
-
-
Save tahoemph/34a77f6898bc292d04540aa734c4d9b6 to your computer and use it in GitHub Desktop.
Collection of useful postgres queries both found and made
This file contains 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
-- table + index sizes | |
SELECT | |
table_name, | |
pg_size_pretty(table_size) AS table_size, | |
pg_size_pretty(indexes_size) AS indexes_size, | |
pg_size_pretty(total_size) AS total_size | |
FROM ( | |
SELECT | |
table_name, | |
pg_table_size(table_name) AS table_size, | |
pg_indexes_size(table_name) AS indexes_size, | |
pg_total_relation_size(table_name) AS total_size | |
FROM ( | |
SELECT ('"' || table_schema || '"."' || table_name || '"') AS table_name | |
FROM information_schema.tables | |
) AS all_tables | |
ORDER BY total_size DESC | |
) AS pretty_sizes limit 10; | |
-- tables + schema table and index sizes | |
select schemaname as table_schema, | |
relname as table_name, | |
pg_size_pretty(pg_total_relation_size(relid)) as total_size, | |
pg_size_pretty(pg_relation_size(relid)) as data_size, | |
pg_size_pretty(pg_total_relation_size(relid) - pg_relation_size(relid)) | |
as external_size | |
from pg_catalog.pg_statio_user_tables | |
order by pg_total_relation_size(relid) desc, | |
pg_relation_size(relid) desc; | |
-- query times | |
select * from pg_stat_statements order by total_time desc; | |
-- index scan heavies | |
SELECT | |
relname AS TableName, | |
to_char(seq_scan, '999,999,999,999') AS TotalSeqScan, | |
to_char(idx_scan, '999,999,999,999') AS TotalIndexScan, | |
to_char(n_live_tup, '999,999,999,999') AS TableRows, | |
pg_size_pretty(pg_relation_size(relname :: regclass)) AS TableSize | |
FROM pg_stat_all_tables | |
WHERE schemaname = 'public' | |
AND 50 * seq_scan > idx_scan -- more then 2% | |
AND n_live_tup > 10000 | |
AND pg_relation_size(relname :: regclass) > 5000000 | |
ORDER BY relname ASC; | |
-- Table queries by weight | |
with table_stats as ( | |
select psut.relname, | |
psut.n_live_tup, | |
1.0 * psut.idx_scan / greatest(1, psut.seq_scan + psut.idx_scan) as index_use_ratio | |
from pg_stat_user_tables psut | |
order by psut.n_live_tup desc | |
), | |
table_io as ( | |
select psiut.relname, | |
sum(psiut.heap_blks_read) as table_page_read, | |
sum(psiut.heap_blks_hit) as table_page_hit, | |
sum(psiut.heap_blks_hit) / greatest(1, sum(psiut.heap_blks_hit) + sum(psiut.heap_blks_read)) as table_hit_ratio | |
from pg_statio_user_tables psiut | |
group by psiut.relname | |
order by table_page_read desc | |
), | |
index_io as ( | |
select psiui.relname, | |
psiui.indexrelname, | |
sum(psiui.idx_blks_read) as idx_page_read, | |
sum(psiui.idx_blks_hit) as idx_page_hit, | |
1.0 * sum(psiui.idx_blks_hit) / greatest(1.0, sum(psiui.idx_blks_hit) + sum(psiui.idx_blks_read)) as idx_hit_ratio | |
from pg_statio_user_indexes psiui | |
group by psiui.relname, psiui.indexrelname | |
order by sum(psiui.idx_blks_read) desc | |
) | |
select ts.relname, ts.n_live_tup, ts.index_use_ratio, | |
ti.table_page_read, ti.table_page_hit, ti.table_hit_ratio, | |
ii.indexrelname, ii.idx_page_read, ii.idx_page_hit, ii.idx_hit_ratio | |
from table_stats ts | |
left outer join table_io ti | |
on ti.relname = ts.relname | |
left outer join index_io ii | |
on ii.relname = ts.relname | |
order by table_hit_ratio; | |
-- indexes on table | |
select tablename,indexname, tablespace,indexdef from pg_indexes where tablename = 'dw_hourly_products'; | |
-- indexes by weight and usage | |
SELECT | |
t.schemaname, | |
t.tablename, | |
indexname, | |
c.reltuples AS num_rows, | |
pg_relation_size(quote_ident(t.schemaname)::text || '.' || quote_ident(t.tablename)::text) AS table_size, | |
pg_relation_size(quote_ident(t.schemaname)::text || '.' || quote_ident(indexrelname)::text) AS index_size, | |
CASE WHEN indisunique THEN 'Y' | |
ELSE 'N' | |
END AS UNIQUE, | |
number_of_scans, | |
tuples_read, | |
tuples_fetched | |
FROM pg_tables t | |
LEFT OUTER JOIN pg_class c ON t.tablename = c.relname | |
LEFT OUTER JOIN ( | |
SELECT | |
c.relname AS ctablename, | |
ipg.relname AS indexname, | |
x.indnatts AS number_of_columns, | |
idx_scan AS number_of_scans, | |
idx_tup_read AS tuples_read, | |
idx_tup_fetch AS tuples_fetched, | |
indexrelname, | |
indisunique, | |
schemaname | |
FROM pg_index x | |
JOIN pg_class c ON c.oid = x.indrelid | |
JOIN pg_class ipg ON ipg.oid = x.indexrelid | |
JOIN pg_stat_all_indexes psai ON x.indexrelid = psai.indexrelid | |
) AS foo ON t.tablename = foo.ctablename AND t.schemaname = foo.schemaname | |
WHERE t.schemaname NOT IN ('pg_catalog', 'information_schema') | |
ORDER BY index_size desc, table_size desc; | |
-- dup indexes (flaky) | |
SELECT pg_size_pretty(SUM(pg_relation_size(idx))::BIGINT) AS SIZE, | |
(array_agg(idx))[1] AS idx1, (array_agg(idx))[2] AS idx2, | |
(array_agg(idx))[3] AS idx3, (array_agg(idx))[4] AS idx4 | |
FROM ( | |
SELECT indexrelid::regclass AS idx, (indrelid::text ||E'\n'|| indclass::text ||E'\n'|| indkey::text ||E'\n'|| | |
COALESCE(indexprs::text,'')||E'\n' || COALESCE(indpred::text,'')) AS KEY | |
FROM pg_index) sub | |
GROUP BY KEY HAVING COUNT(*)>1 | |
ORDER BY SUM(pg_relation_size(idx)) DESC; | |
-- list locks | |
SELECT DISTINCT age(now(), query_start) AS age, pg_stat_activity.pid,pg_locks.granted,pg_stat_activity.application_name,pg_stat_activity.backend_start, pg_stat_activity.xact_start, pg_stat_activity.state_change, pg_stat_activity.state, pg_stat_activity.query_start, left(pg_stat_activity.query, 60) | |
FROM pg_stat_activity, pg_locks | |
WHERE pg_locks.pid = pg_stat_activity.pid | |
select pid as process_id, | |
usename as username, | |
datname as database_name, | |
client_addr as client_address, | |
application_name, | |
query, | |
backend_start, | |
state, | |
state_change | |
from pg_stat_activity; | |
select * from pg_stat_activity; | |
-- things blocked by locks | |
select pid, | |
usename, | |
pg_blocking_pids(pid) as blocked_by, | |
query as blocked_query | |
from pg_stat_activity | |
where cardinality(pg_blocking_pids(pid)) > 0; | |
-- Things blocked and what they are blocked by | |
select a1.pid, | |
a1.usename, | |
a1.query as blocked_query, | |
a2.usename as blocking_usename, | |
a2.pid as blocking_pid, | |
a2.query as blocking_query | |
from pg_stat_activity a1 join pg_stat_activity a2 on a2.pid = any(pg_blocking_pids(a1.pid)) | |
where cardinality(pg_blocking_pids(a1.pid)) > 0; |
Sign up for free
to join this conversation on GitHub.
Already have an account?
Sign in to comment