Skip to content

Instantly share code, notes, and snippets.

Show Gist options
  • Star 0 You must be signed in to star a gist
  • Fork 0 You must be signed in to fork a gist
  • Save helderjnpinto/d8a69a4ef1389b1ab76823d50aa19af8 to your computer and use it in GitHub Desktop.
Save helderjnpinto/d8a69a4ef1389b1ab76823d50aa19af8 to your computer and use it in GitHub Desktop.
Useful PostgreSQL Queries and Commands
-- show running queries (pre 9.2)
SELECT procpid, age(clock_timestamp(), query_start), usename, current_query
FROM pg_stat_activity
WHERE current_query != '<IDLE>' AND current_query NOT ILIKE '%pg_stat_activity%'
ORDER BY query_start desc;
-- show running queries (9.2)
SELECT pid, age(clock_timestamp(), query_start), usename, query
FROM pg_stat_activity
WHERE query != '<IDLE>' AND query NOT ILIKE '%pg_stat_activity%'
ORDER BY query_start desc;
-- show running queries (9.2) NO EMPTY QUERIES
SELECT pid, age(clock_timestamp(), query_start), usename, query
FROM pg_stat_activity
WHERE query != '<IDLE>' AND query NOT ILIKE '%pg_stat_activity%' AND query NOT ILIKE ''
ORDER BY query_start desc;
-- kill running query
SELECT pg_cancel_backend(procpid);
-- kill idle query
SELECT pg_terminate_backend(procpid);
-- vacuum command
VACUUM (VERBOSE, ANALYZE);
-- all database users
select * from pg_stat_activity where current_query not like '<%';
-- all databases and their sizes
select * from pg_user;
-- all tables and their size, with/without indexes
select datname, pg_size_pretty(pg_database_size(datname))
from pg_database
order by pg_database_size(datname) desc;
-- cache hit rates (should not be less than 0.99)
SELECT sum(heap_blks_read) as heap_read, sum(heap_blks_hit) as heap_hit, (sum(heap_blks_hit) - sum(heap_blks_read)) / sum(heap_blks_hit) as ratio
FROM pg_statio_user_tables;
-- table index usage rates (should not be less than 0.99)
SELECT relname, 100 * idx_scan / (seq_scan + idx_scan) percent_of_times_index_used, n_live_tup rows_in_table
FROM pg_stat_user_tables
ORDER BY n_live_tup DESC;
-- how many indexes are in cache
SELECT sum(idx_blks_read) as idx_read, sum(idx_blks_hit) as idx_hit, (sum(idx_blks_hit) - sum(idx_blks_read)) / sum(idx_blks_hit) as ratio
FROM pg_statio_user_indexes;
-- Slow queries
SELECT
now() - query_start as "runtime",
usename,
datname,
-- not available on PostgreSQL < 9.6
wait_event,
-- not available on PostgreSQL < 9.2
state,
-- current_query on PostgreSQL < 9.2
query
FROM
pg_stat_activity
WHERE
-- can't use 'runtime' here
now() - query_start > '30 seconds'::interval
ORDER BY
runtime DESC;
-- Blocked queries
SELECT
pid,
usename,
pg_blocking_pids(pid) AS blocked_by_pids,
query AS blocked_query
FROM
pg_stat_activity
WHERE
cardinality(pg_blocking_pids(pid)) > 0;
-- Age of current queries as been executed
SELECT
pid,
age(clock_timestamp(), query_start),
usename,
application_name,
query
FROM
pg_stat_activity
WHERE
state != 'idle'
AND
query NOT ILIKE '%pg_stat_activity%'
ORDER BY
query_start DESC;
-- Dump database on remote host to file
$ pg_dump -U username -h hostname databasename > dump.sql
-- Import dump into existing database
$ psql -d newdb -f dump.sql
Sign up for free to join this conversation on GitHub. Already have an account? Sign in to comment