Re: Queries for unused/useless indexes

From: Melvin Davidson <melvin6925(at)gmail(dot)com>
To: "Peter J(dot) Holzer" <hjp-pgsql(at)hjp(dot)at>
Cc: "pgsql-general(at)postgresql(dot)org" <pgsql-general(at)postgresql(dot)org>
Subject: Re: Queries for unused/useless indexes
Date: 2015-05-25 16:25:01
Message-ID: CANu8Fix5xUGs5a_wSczEAaYTJtHzT97deibSLPeGdBHCvfER8A@mail.gmail.com
Views: Raw Message | Whole Thread | Download mbox | Resend email
Thread:
Lists: pgsql-general

I'm not sure why you are using "pg_stat_user_indexes". My original query
below uses "pg_stat_all_indexes" and the schema names are joined and it
does work.

SELECT n.nspname as schema,
i.relname as table,
i.indexrelname as index,
i.idx_scan,
i.idx_tup_read,
i.idx_tup_fetch,
pg_size_pretty(pg_relation_size(quote_ident(n.nspname) || '.' ||
quote_ident(i.relname))) AS table_size,
pg_size_pretty(pg_relation_size(quote_ident(n.nspname) || '.' ||
quote_ident(i.indexrelname))) AS index_size,
pg_get_indexdef(idx.indexrelid) as idx_definition
FROM 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 < 200
AND NOT idx.indisprimary
AND NOT idx.indisunique
ORDER BY 1, 2, 3;

On Mon, May 25, 2015 at 10:41 AM, Peter J. Holzer <hjp-pgsql(at)hjp(dot)at> wrote:

> On 2015-05-22 09:41:57 -0400, Melvin Davidson wrote:
> > 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;
>
> Thanks, that's useful.
>
> However, it doesn't quite work if there are indexes with the same name
> in different schemas. Better join on the schemaname, too:
>
> FROM pg_stat_user_indexes AS idstat
> JOIN pg_indexes AS idx ON indexrelname = indexname and
> idstat.schemaname = idx.schemaname
> JOIN pg_stat_user_tables AS tabstat ON idstat.relname =
> tabstat.relname and idstat.schemaname = tabstat.schemaname
>
> (for some reason that makes it a lot slower, though)
>
> hp
>
> --
> _ | Peter J. Holzer | I want to forget all about both belts and
> |_|_) | | suspenders; instead, I want to buy pants
> | | | hjp(at)hjp(dot)at | that actually fit.
> __/ | http://www.hjp.at/ | -- http://noncombatant.org/
>

--
*Melvin Davidson*
I reserve the right to fantasize. Whether or not you
wish to share my fantasy is entirely up to you.

In response to

Responses

Browse pgsql-general by date

  From Date Subject
Next Message Peter J. Holzer 2015-05-25 16:39:39 Re: Queries for unused/useless indexes
Previous Message Guillaume Lelarge 2015-05-25 15:35:20 Re: Strange replication problem - segment restored from archive but still requested from master