Forked from rgreenjr/postgres_queries_and_commands.sql
Last active
February 25, 2021 12:11
-
-
Save kiurtis/e485873ca6d978c4a02555a776aa08f5 to your computer and use it in GitHub Desktop.
Useful PostgreSQL Queries and Commands
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
-- 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; | |
-- 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, | |
CASE WHEN (seq_scan + idx_scan) != 0 | |
THEN 100.0 * idx_scan / (seq_scan + idx_scan) | |
ELSE 0 | |
END AS percent_of_times_index_used, | |
n_live_tup AS rows_in_table | |
FROM pg_stat_user_tables | |
ORDER BY n_live_tup DESC; | |
-- Checks if there are more sequence scans than index scans. If the table is small, it gets ignored, since Postgres seems to prefer sequence scans for them. | |
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 than 2% | |
AND n_live_tup > 10000 | |
AND pg_relation_size(relname :: regclass) > 5000000 | |
ORDER BY relname ASC; | |
-- 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