Skip to content

Instantly share code, notes, and snippets.

@craigkerstiens
Created September 28, 2012 21:16
Show Gist options
  • Star 17 You must be signed in to star a gist
  • Fork 0 You must be signed in to fork a gist
  • Save craigkerstiens/a0d9038fc5f86312ac9e to your computer and use it in GitHub Desktop.
Save craigkerstiens/a0d9038fc5f86312ac9e to your computer and use it in GitHub Desktop.
Understanding Database Performance

Query for understanding how often indexes are used

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;

Query for overall cache hit rate

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;

Query for index cache hit rate

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;

pixel

Sign up for free to join this conversation on GitHub. Already have an account? Sign in to comment