Re: n00b question re: indexes and constraints

From: Rui DeSousa <rui(at)crazybean(dot)net>
To: Wells Oliver <wells(dot)oliver(at)gmail(dot)com>
Cc: "David G(dot) Johnston" <david(dot)g(dot)johnston(at)gmail(dot)com>, pgsql-admin <pgsql-admin(at)postgresql(dot)org>
Subject: Re: n00b question re: indexes and constraints
Date: 2020-04-22 21:25:29
Message-ID: CABDA054-5DF4-4C09-9DDC-F544E3DBC043@crazybean.net
Views: Raw Message | Whole Thread | Download mbox | Resend email
Thread:
Lists: pgsql-admin

> On Apr 22, 2020, at 2:39 PM, Wells Oliver <wells(dot)oliver(at)gmail(dot)com> wrote:
>
> Thanks, I should have been more specific, these are unique constraints I am concerned about: so yeah, creating an index on a set of columns where there's a unique constraint is redundant, correct?
>

Correct. Here is a view that I created to help find duplicate indexes in such cases where redundant indexes where created.

create or replace view duplicate_index
as
select base.indrelid::regclass as table_name
, string_agg((dup.indexrelid::regclass)::text, E'\n') as indexes
, pg_size_pretty(avg(pg_relation_size(dup.indexrelid))) as avg_size
from pg_index base
join pg_index dup on dup.indrelid = base.indrelid -- table identifier
and dup.indkey = base.indkey -- columns indexed
and dup.indclass = base.indclass -- columns types
and (
dup.indexprs = base.indexprs -- expression predicate for columns
or (
dup.indexprs is null
and base.indexprs is null
)
)
and (
dup.indpred = base.indpred -- expression predicate for where clause
or (
dup.indpred is null
and base.indpred is null
)
)
and dup.indexrelid != base.indexrelid --index identifier
group by base.indrelid::regclass
, concat(base.indkey::text, base.indclass::text, base.indexprs, base.indpred)
order by avg_size desc
, base.indrelid::regclass
;

In response to

Browse pgsql-admin by date

  From Date Subject
Next Message Ashok kumar Mani 2020-04-23 06:14:21 Help needed for replication issue
Previous Message David G. Johnston 2020-04-22 18:48:19 Re: n00b question re: indexes and constraints