Skip to content

Instantly share code, notes, and snippets.

@khiemdoan
Last active June 7, 2024 07:23
Show Gist options
  • Save khiemdoan/d8e13607b4b8a887e801ea422f6744b4 to your computer and use it in GitHub Desktop.
Save khiemdoan/d8e13607b4b8a887e801ea422f6744b4 to your computer and use it in GitHub Desktop.

Find slow queries

Ref: https://vertabelo.com/blog/using-sql-to-monitor-a-postgresql-database/

select now() - query_start AS elapsed, 
query AS sql_text, 
datname AS database, 
usename AS username
from    pg_stat_activity
where now() - query_start > '00:01:00'   /* we only want queries lasting more than one minute */
and state = 'active'
order by 1 desc

Check number of connections

Ref: https://stackoverflow.com/questions/5267715/right-query-to-get-the-current-number-of-connections-in-a-postgresql-db

select * from
(select count(*) used from pg_stat_activity) q1,
(select setting::int res_for_super from pg_settings where name=$$superuser_reserved_connections$$) q2,
(select setting::int max_conn from pg_settings where name=$$max_connections$$) q3;

Check which table need to vacuum

select relname, n_live_tup, n_dead_tup, last_vacuum, last_autovacuum, last_analyze, last_autoanalyze 
from pg_stat_user_tables
order by n_dead_tup desc;

Check size of databases

Ref: https://stackoverflow.com/questions/2596624/how-do-you-find-the-disk-size-of-a-postgres-postgresql-table-and-its-indexes

SELECT
    table_name,
    pg_size_pretty(table_size) AS table_size,
    pg_size_pretty(indexes_size) AS indexes_size,
    pg_size_pretty(total_size) AS total_size
FROM (
    SELECT
        table_name,
        pg_table_size(table_name) AS table_size,
        pg_indexes_size(table_name) AS indexes_size,
        pg_total_relation_size(table_name) AS total_size
    FROM (
        SELECT ('"' || table_schema || '"."' || table_name || '"') AS table_name
        FROM information_schema.tables
    ) AS all_tables
    ORDER BY total_size DESC
) AS pretty_sizes;
Sign up for free to join this conversation on GitHub. Already have an account? Sign in to comment