Forked from rgreenjr/postgres_queries_and_commands.sql
Last active
February 22, 2018 14:48
-
-
Save sbussetti/3cd81127da2547ba61d75ff8f46b238d to your computer and use it in GitHub Desktop.
Useful PostgreSQL Queries and Commands
This file contains hidden or 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
-- All commands assume 9.2 + | |
-- show running queries | |
SELECT pid, age(query_start, clock_timestamp()), state, waiting, usename, query | |
FROM pg_stat_activity | |
WHERE query != '<IDLE>' | |
AND query NOT ILIKE '%pg_stat_activity%' | |
AND state != 'idle' | |
ORDER BY query_start desc; | |
-- kill running query | |
SELECT pg_cancel_backend(procpid); | |
-- forcibly kill running/idle query | |
SELECT pg_terminate_backend(procpid); | |
-- vacuum command | |
VACUUM (VERBOSE, ANALYZE); | |
-- all database users | |
select * from pg_user; | |
-- all databases and their sizes | |
select datname, pg_size_pretty(pg_database_size(datname)) | |
from pg_database | |
order by pg_database_size(datname) desc; | |
-- all tables and their size, with/without indexes | |
SELECT *, pg_size_pretty(total_bytes) AS total | |
, pg_size_pretty(index_bytes) AS INDEX | |
, pg_size_pretty(toast_bytes) AS toast | |
, pg_size_pretty(table_bytes) AS TABLE | |
FROM ( | |
SELECT *, total_bytes-index_bytes-COALESCE(toast_bytes,0) AS table_bytes FROM ( | |
SELECT c.oid,nspname AS table_schema, relname AS TABLE_NAME | |
, c.reltuples AS row_estimate | |
, pg_total_relation_size(c.oid) AS total_bytes | |
, pg_indexes_size(c.oid) AS index_bytes | |
, pg_total_relation_size(reltoastrelid) AS toast_bytes | |
FROM pg_class c | |
LEFT JOIN pg_namespace n ON n.oid = c.relnamespace | |
WHERE relkind = 'r' | |
) a | |
) a; | |
-- all tables with total size including indexes, relations | |
SELECT nspname || '.' || relname AS "relation", | |
pg_size_pretty(pg_total_relation_size(C.oid)) AS "total_size" | |
FROM pg_class C | |
LEFT JOIN pg_namespace N ON (N.oid = C.relnamespace) | |
WHERE nspname NOT IN ('pg_catalog', 'information_schema') | |
AND C.relkind <> 'i' | |
AND nspname !~ '^pg_toast' | |
ORDER BY pg_total_relation_size(C.oid) DESC | |
LIMIT 20; | |
-- 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; | |
-- 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