Re: Ideas to deal with table corruption

From: Rui DeSousa <rui(dot)desousa(at)icloud(dot)com>
To: Corey Taylor <corey(dot)taylor(dot)fl(at)gmail(dot)com>
Cc: Melvin Davidson <melvin6925(at)gmail(dot)com>, Peter Geoghegan <pg(at)bowt(dot)ie>, Luis Marin <luismarinaray(at)gmail(dot)com>, pgsql-admin(at)postgresql(dot)org, pgsql-general General <pgsql-general(at)postgresql(dot)org>
Subject: Re: Ideas to deal with table corruption
Date: 2018-01-06 19:59:04
Message-ID: 75A0F4D4-2A34-497F-82F9-C04D436F4FF8@icloud.com
Views: Raw Message | Whole Thread | Download mbox | Resend email
Thread:
Lists: pgsql-admin pgsql-general

Correct, and there is no need to create an index on a unique constraint or primary key as they are already implemented via indexes. I can’t count how many duplicate indexes I’ve dropped in the past. I use this view help find duplicates in a given system. Duplicate indexes just use up space and rob performance during updates and inserts.

/*======================================================================================================
q$Id: duplicate_index.sql 1 2015-12-19 15:40:29Z rui $
Description: Find duplicate indexes
======================================================================================================*/
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 Leroy Tennison 2018-01-08 03:10:58 Issue with WAL files in streaming replication
Previous Message scott ribe 2018-01-06 19:14:56 Re: Ideas to deal with table corruption

Browse pgsql-general by date

  From Date Subject
Next Message Travis Allison 2018-01-06 20:36:34 Re: What generates pg_config.h?
Previous Message scott ribe 2018-01-06 19:14:56 Re: Ideas to deal with table corruption