Skip to content

Instantly share code, notes, and snippets.

@yelizariev
Last active March 6, 2018 10:16
Show Gist options
  • Save yelizariev/90d64b02c50c655738becdc657944121 to your computer and use it in GitHub Desktop.
Save yelizariev/90d64b02c50c655738becdc657944121 to your computer and use it in GitHub Desktop.
Postgresql
--- connection count
SELECT sum(numbackends) FROM pg_stat_database;
--- long running queries
SELECT
pid,
now() - pg_stat_activity.query_start AS duration,
query,
state
FROM pg_stat_activity
WHERE (now() - pg_stat_activity.query_start) > interval '5 minutes';
--- long statements https://www.postgresql.org/docs/9.5/static/pgstatstatements.html
select pg_stat_statements_reset();
SELECT calls, total_time/1000, rows, 100.0 * shared_blks_hit /
nullif(shared_blks_hit + shared_blks_read, 0) AS hit_percent, query
FROM pg_stat_statements ORDER BY total_time DESC LIMIT 5;
--- blocks. From https://wiki.postgresql.org/wiki/Lock_Monitoring
SELECT blocked_locks.pid AS blocked_pid,
blocked_activity.usename AS blocked_user,
blocking_locks.pid AS blocking_pid,
blocking_activity.usename AS blocking_user,
blocked_activity.query AS blocked_statement,
blocking_activity.query AS current_statement_in_blocking_process
FROM pg_catalog.pg_locks blocked_locks
JOIN pg_catalog.pg_stat_activity blocked_activity ON blocked_activity.pid = blocked_locks.pid
JOIN pg_catalog.pg_locks blocking_locks
ON blocking_locks.locktype = blocked_locks.locktype
AND blocking_locks.DATABASE IS NOT DISTINCT FROM blocked_locks.DATABASE
AND blocking_locks.relation IS NOT DISTINCT FROM blocked_locks.relation
AND blocking_locks.page IS NOT DISTINCT FROM blocked_locks.page
AND blocking_locks.tuple IS NOT DISTINCT FROM blocked_locks.tuple
AND blocking_locks.virtualxid IS NOT DISTINCT FROM blocked_locks.virtualxid
AND blocking_locks.transactionid IS NOT DISTINCT FROM blocked_locks.transactionid
AND blocking_locks.classid IS NOT DISTINCT FROM blocked_locks.classid
AND blocking_locks.objid IS NOT DISTINCT FROM blocked_locks.objid
AND blocking_locks.objsubid IS NOT DISTINCT FROM blocked_locks.objsubid
AND blocking_locks.pid != blocked_locks.pid
JOIN pg_catalog.pg_stat_activity blocking_activity ON blocking_activity.pid = blocking_locks.pid
WHERE NOT blocked_locks.GRANTED;
--- Kill query
select pg_cancel_backend(1234); -- soft
select pg_terminate_backend(1234); -- hard
# understanding wal and checkpoint:
#
# https://www.postgresql.org/docs/9.5/static/wal-intro.html
# https://blog.2ndquadrant.com/basics-of-tuning-checkpoints/
checkpoint_timeout=45min # default is 5 min
# To get more logs:
log_min_duration_statement='100333' # log quieres that are running more than 100 sec
log_checkpoints = 'on'
shared_preload_libraries = 'pg_stat_statements'
# pg_stat_statements also requires extra package to be installed:
# bash: apt-get install postgresql-contrib
# psql: CREATE EXTENSION pg_stat_statements;
--- REINDEX accounting tables
REINDEX TABLE account_move;
REINDEX TABLE account_move_line;
REINDEX TABLE account_bank_statement_line;
REINDEX TABLE account_payment;
VACUUM FULL ANALYZE account_move_line;
Sign up for free to join this conversation on GitHub. Already have an account? Sign in to comment