You signed in with another tab or window. Reload to refresh your session.You signed out in another tab or window. Reload to refresh your session.You switched accounts on another tab or window. Reload to refresh your session.Dismiss alert
SELECT (NOW() - query_start) as duration, pid, usename, application_name, client_addr, client_port, backend_start, query_start,
wait_event, wait_event_type, state, query
FROM pg_stat_activity
WHERE pid <> pg_backend_pid()
AND state <>'idle'ORDER BY query_start ASC;
Long running queries
SELECT (NOW() - query_start) as duration, pid, usename, application_name, client_addr, client_port, backend_start, query_start,
wait_event, wait_event_type, state, query
FROM pg_stat_activity
WHERE pid <> pg_backend_pid()
AND state <>'idle'AND age(now(),pg_stat_activity.query_start) >'00:05:00'ORDER BY query_start ASC
Killing long running queries
SELECT
pg_cancel_backend(pid),
(NOW() - query_start) as duration, pid, usename, application_name, client_addr, client_port, backend_start, query_start,
wait_event, wait_event_type, state, query
FROM pg_stat_activity
WHERE pid <> pg_backend_pid()
AND state <>'idle'AND age(now(),pg_stat_activity.query_start) >'00:10:00'ORDER BY query_start ASC-- https://github.com/heroku/heroku-pg-extras/tree/master/commands-- violent: pg_terminate_backend / pg_cancel_backend
Locks
SELECTpg_stat_activity.pid,
pg_class.relname,
pg_locks.transactionid,
pg_locks.granted,
pg_stat_activity.queryAS query_snippet,
age(now(),pg_stat_activity.query_start) AS"age"FROM pg_stat_activity,pg_locks left
OUTER JOIN pg_class
ON (pg_locks.relation=pg_class.oid)
WHEREpg_stat_activity.query<>'<insufficient privilege>'ANDpg_locks.pid=pg_stat_activity.pidANDpg_locks.mode='ExclusiveLock'ANDpg_stat_activity.pid<> pg_backend_pid() order by query_start;
Blocking Queries
SELECTbl.pidAS blocked_pid,
ka.queryAS blocking_statement,
now() -ka.query_startAS blocking_duration,
kl.pidAS blocking_pid,
a.queryAS blocked_statement,
now() -a.query_startAS blocked_duration
FROMpg_catalog.pg_locks bl
JOINpg_catalog.pg_stat_activity a
ONbl.pid=a.pidJOINpg_catalog.pg_locks kl
JOINpg_catalog.pg_stat_activity ka
ONkl.pid=ka.pidONbl.transactionid=kl.transactionidANDbl.pid!=kl.pidWHERE NOT bl.granted
SELECTblocked_locks.pidAS blocked_pid,
blocked_activity.usenameAS blocked_user,
blocking_locks.pidAS blocking_pid,
blocking_activity.usenameAS blocking_user,
blocked_activity.queryAS blocked_statement,
blocking_activity.queryAS current_statement_in_blocking_process
FROMpg_catalog.pg_locks blocked_locks
JOINpg_catalog.pg_stat_activity blocked_activity ONblocked_activity.pid=blocked_locks.pidJOINpg_catalog.pg_locks blocking_locks
ONblocking_locks.locktype=blocked_locks.locktypeANDblocking_locks.DATABASE IS NOT DISTINCT FROMblocked_locks.DATABASEANDblocking_locks.relation IS NOT DISTINCT FROMblocked_locks.relationANDblocking_locks.page IS NOT DISTINCT FROMblocked_locks.pageANDblocking_locks.tuple IS NOT DISTINCT FROMblocked_locks.tupleANDblocking_locks.virtualxid IS NOT DISTINCT FROMblocked_locks.virtualxidANDblocking_locks.transactionid IS NOT DISTINCT FROMblocked_locks.transactionidANDblocking_locks.classid IS NOT DISTINCT FROMblocked_locks.classidANDblocking_locks.objid IS NOT DISTINCT FROMblocked_locks.objidANDblocking_locks.objsubid IS NOT DISTINCT FROMblocked_locks.objsubidANDblocking_locks.pid!=blocked_locks.pidJOINpg_catalog.pg_stat_activity blocking_activity ONblocking_activity.pid=blocking_locks.pidWHERE NOT blocked_locks.GRANTED;
Expensive Queries
SELECT*FROM pg_stat_statements
WHERE calls >=5ORDER BY mean_time DESCLIMIT100
Index Size/Usage
SELECTt.tablename,
indexname,
c.reltuplesAS num_rows,
pg_size_pretty(pg_relation_size(quote_ident(t.tablename)::text)) AS table_size,
pg_size_pretty(pg_relation_size(quote_ident(indexrelname)::text)) AS index_size,
CASE WHEN indisunique THEN 'Y'
ELSE 'N'
END AS UNIQUE,
idx_scan AS number_of_scans,
idx_tup_read AS tuples_read,
idx_tup_fetch AS tuples_fetched
FROM pg_tables t
LEFT OUTER JOIN pg_class c ONt.tablename=c.relnameLEFT OUTER JOIN
( SELECTc.relnameAS ctablename, ipg.relnameAS indexname, x.indnattsAS number_of_columns, idx_scan, idx_tup_read, idx_tup_fetch, indexrelname, indisunique FROM pg_index x
JOIN pg_class c ONc.oid=x.indrelidJOIN pg_class ipg ONipg.oid=x.indexrelidJOIN pg_stat_all_indexes psai ONx.indexrelid=psai.indexrelid )
AS foo
ONt.tablename=foo.ctablenameWHEREt.schemaname='public'ORDER BY1,2;
Non-unique index usage
SELECTt.tablename,
indexname,
c.reltuplesAS num_rows,
pg_size_pretty(pg_relation_size(quote_ident(t.tablename)::text)) AS table_size,
pg_size_pretty(pg_relation_size(quote_ident(indexrelname)::text)) AS index_size,
idx_scan AS number_of_scans,
idx_tup_read AS tuples_read,
idx_tup_fetch AS tuples_fetched
FROM pg_tables t
LEFT OUTER JOIN pg_class c ONt.tablename=c.relnameLEFT OUTER JOIN
( SELECTc.relnameAS ctablename, ipg.relnameAS indexname, x.indnattsAS number_of_columns, idx_scan, idx_tup_read, idx_tup_fetch, indexrelname, indisunique FROM pg_index x
JOIN pg_class c ONc.oid=x.indrelidJOIN pg_class ipg ONipg.oid=x.indexrelidJOIN pg_stat_all_indexes psai ONx.indexrelid=psai.indexrelid )
AS foo
ONt.tablename=foo.ctablenameWHEREt.schemaname='public'AND NOT indisunique
ORDER BY1,2;
Replication
-- show logical replication slotsSELECT*FROM pg_replication_slots;
-- Drop bad replication slotselect pg_drop_replication_slot('w65jlk5x6jyxkpou_00016401_60187b16_5cb2_4d11_b756_7dc72e5dd5a6')
AutoVac
-- Disable AutoVacALTERTABLE investments SET (autovacuum_enabled = false, toast.autovacuum_enabled= false);
-- reenableALTERTABLE investments SET (autovacuum_enabled = true, toast.autovacuum_enabled= true);
Data Size
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) DESCLIMIT20;
Table Size
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')
AND relname IN ('TABLE_NAME')
ORDER BY pg_relation_size(C.oid) DESCLIMIT100;
Wraparound vac "todo list"
SELECToid::regclass::textAS table,
age(relfrozenxid) AS xid_age,
mxid_age(relminmxid) AS mxid_age,
least(
(SELECT setting::bigintFROM pg_settings
WHERE name ='autovacuum_freeze_max_age') - age(relfrozenxid),
(SELECT setting::bigintFROM pg_settings
WHERE name ='autovacuum_multixact_freeze_max_age') - mxid_age(relminmxid)
) AS tx_before_wraparound_vacuum,
pg_size_pretty(pg_total_relation_size(oid)) AS size,
pg_stat_get_last_autovacuum_time(oid) AS last_autovacuum
FROM pg_class
WHERE relfrozenxid !=0ANDoid>16384ORDER BY tx_before_wraparound_vacuum;
Misc
-- show optionsSELECT relname, reloptions FROM pg_class;