Re: Best practice when reindexing in production

From: Matheus de Oliveira <matioli(dot)matheus(at)gmail(dot)com>
To: Niels Kristian Schjødt <nielskristian(at)autouncle(dot)com>
Cc: Magnus Hagander <magnus(at)hagander(dot)net>, "pgsql-performance(at)postgresql(dot)org list" <pgsql-performance(at)postgresql(dot)org>
Subject: Re: Best practice when reindexing in production
Date: 2013-05-29 13:12:18
Message-ID: CAJghg4Kq9XCS2njFEzzcc83mzuc9wnCv_V4HgZme0ZAMCSS2NA@mail.gmail.com
Views: Raw Message | Whole Thread | Download mbox | Resend email
Thread:
Lists: pgsql-performance

On Wed, May 29, 2013 at 9:41 AM, Niels Kristian Schjødt <
nielskristian(at)autouncle(dot)com> wrote:

> Thanks
>
> Can you think of a way to select all the indexes programmatically from a
> table and run CREATE INDEX CONCURRENTLY for each of them, so that I don't
> have to hardcode every index name + create statement ?
>
>
>
You could do something like this (which considers you use simple names for
your indexes, where simple ~ [a-z_][a-z0-9_]*):

SELECT
regexp_replace(i.indexdef, '^CREATE( UNIQUE)? INDEX (.*) ON (.*)',
'CREATE\1 INDEX CONCURRENTLY tmp_\2 ON \3;') || E'\n'
|| E'BEGIN;\n'
|| 'DROP INDEX ' || i.indexname || E';\n'
|| 'ALTER INDEX tmp_' || i.indexname || ' RENAME TO ' || i.indexname ||
E';\n'
|| E'COMMIT;\n'
FROM pg_indexes i
WHERE schemaname !~ '^(pg_|information_schema$)';

Although this one is *really simple* and *error phrone*, because it does
not consider at least two things: index that are constraints and index that
has FK depending on it. For the first case, you only need to change the
constraint to use the index and the DROP command. As for the second case,
you would need to remove the FKs, drop the old one and recreate the FK
(inside a transaction, of course), but this could be really slow, a reindex
for this case would be simpler and perhaps faster.

Regards,
--
Matheus de Oliveira
Analista de Banco de Dados
Dextra Sistemas - MPS.Br nível F!
www.dextra.com.br/postgres

In response to

Responses

Browse pgsql-performance by date

  From Date Subject
Next Message Igor Neyman 2013-05-29 13:55:49 Re: Best practice when reindexing in production
Previous Message Magnus Hagander 2013-05-29 13:08:40 Re: Best practice when reindexing in production