Queries for unused/useless indexes

From: Melvin Davidson <melvin6925(at)gmail(dot)com>
To: "pgsql-general(at)postgresql(dot)org" <pgsql-general(at)postgresql(dot)org>
Subject: Queries for unused/useless indexes
Date: 2015-05-22 13:41:57
Message-ID: CANu8FixpRb65_7TPKpZ=5r7ndZrKctZZaYwjO0XKpqaXy9JYjw@mail.gmail.com
Views: Raw Message | Whole Thread | Download mbox | Resend email
Thread:
Lists: pgsql-general

Over the years I've wrote many scripts and queries to track the database
status. Recently I've had to convince a client who thought it was a good
idea to create indexes for every column on every table that it is really a
bad idea. To do so, I wrote useless_indexes2.sql, which shows every index
that has never been scanned. They still didn't believe me, so I wrote
wasted_index_space.sql. That shows how much space is wasted by all the
unused indexes.

I'd like to share those queries with the community, as I know there must be
others out there with the same problem.

/* useless_indexes.sql */
SELECT
idstat.schemaname AS schema,
idstat.relname AS table_name,
indexrelname AS index_name,
idstat.idx_scan AS times_used,
pg_size_pretty(pg_relation_size(quote_ident(idstat.schemaname) ||
'.' || quote_ident(idstat.relname))) AS table_size,
pg_size_pretty(pg_relation_size(quote_ident(idstat.schemaname) ||
'.' || quote_ident(indexrelname))) AS index_size,
n_tup_upd + n_tup_ins + n_tup_del as num_writes,
indexdef AS definition
FROM pg_stat_user_indexes AS idstat
JOIN pg_indexes ON indexrelname = indexname
JOIN pg_stat_user_tables AS tabstat ON idstat.relname = tabstat.relname
WHERE idstat.idx_scan < 200
AND indexdef !~* 'unique'
ORDER BY idstat.schemaname,
idstat.relname,
indexrelname;

/*wasted_index_space.sql
Requires PostgreSQL 8.4 or greater */
WITH s AS(
SELECT SUM(pg_relation_size(quote_ident(n.nspname) || '.' ||
quote_ident(c.relname))::bigint) AS table_size,
pg_size_pretty(SUM(pg_relation_size(quote_ident(n.nspname) || '.' ||
quote_ident(c.relname))::bigint)::bigint) AS table_size_pretty
FROM pg_class c
JOIN pg_namespace n ON (n.oid = c.relnamespace)
WHERE c.relkind = 'r'
AND c.relname NOT LIKE 'pg_%'
AND c.relname NOT LIKE 'sql%'
)
SELECT s.table_size,
s.table_size_pretty,
SUM(pg_relation_size(quote_ident(n.nspname) || '.' ||
quote_ident(i.indexrelname))::bigint) AS unused_idx_size,
pg_size_pretty(SUM(pg_relation_size(quote_ident(n.nspname) || '.' ||
quote_ident(i.indexrelname))::bigint)::bigint) AS unused_idx_size_pretty,
pg_database_size(current_database()) as db_size,
pg_size_pretty(pg_database_size(current_database()))as
db_size_pretty,
pg_size_pretty(pg_database_size(current_database()) -
SUM(pg_relation_size(quote_ident(n.nspname) || '.' ||
quote_ident(i.indexrelname))::bigint)::bigint) as db_minus_wasted_space

FROM s, pg_stat_all_indexes i
JOIN pg_class c ON (c.oid = i.relid)
JOIN pg_namespace n ON (n.oid = c.relnamespace)
JOIN pg_index idx ON (idx.indexrelid = i.indexrelid )
WHERE i.idx_scan = 0
AND NOT idx.indisprimary
AND NOT idx.indisunique
GROUP BY table_size, table_size_pretty;

*Melvin Davidson*

Responses

Browse pgsql-general by date

  From Date Subject
Next Message Tom Lane 2015-05-22 15:02:47 Re: Allowing postgresql to accept 0xff syntax for data types that it makes sense for?
Previous Message John McKown 2015-05-22 13:29:04 Re: Different result depending on order of joins