Vacuumdb error

Lists: pgsql-general
From: Gipsz Jakab <clausewitz45(at)gmail(dot)com>
To: pgsql-general(at)postgresql(dot)org
Subject: Vacuumdb error
Date: 2011-04-14 11:56:13
Message-ID: BANLkTikme98HJ76QRFdF9aHi5Rp0j7xjpw@mail.gmail.com
Views: Raw Message | Whole Thread | Download mbox | Resend email
Lists: pgsql-general

Dear List,

Today morning at 01:00 AM in our PostgreSQL 9.0.3 server a routine
maintenance script has started (vacuumdb --all --full --analyze), and
stopped with this error:

sqlstate=23505ERROR: duplicate key value violates unique constraint
"pg_index_indexrelid_index"
sqlstate=23505DETAIL: Key (indexrelid)=(2678) already exists.

We didn't do or change anything in postgre enviroment (except we raised the
max_lock_per_transaction from 64 to 128)

I've started a search on the internet, because of this error, but I didn't
find anything, that I can use. Any idea? I've checked the postgres DB /
catalogs / pg_catalog / tables / pg_index, and there is the record where
indexrelid=2678, but there is only one record there...

I saw, that somebody has the same problem (with the same ID!), and Tom Lane
and Robert Haas requested the (select ctid,xmin,xmax,* from pg_index;) query
output in a file. See attached.

PostgreSQL: PostgreSQL 9.0.3 on i386-portbld-freebsd8.2, compiled by GCC cc
(GCC) 4.2.1 20070719 [FreeBSD], 32-bit

Thanks, and regards,
Carl

Attachment Content-Type Size
data.csv text/csv 6.9 KB

From: Vidhya Bondre <vbondre(at)zedo(dot)com>
To: Gipsz Jakab <clausewitz45(at)gmail(dot)com>
Cc: pgsql-general(at)postgresql(dot)org
Subject: Re: Vacuumdb error
Date: 2011-04-14 12:00:15
Message-ID: BANLkTinbnkOkkt1EVASQsynPKUdVTam9_w@mail.gmail.com
Views: Raw Message | Whole Thread | Download mbox | Resend email
Lists: pgsql-general

Gipsz,

We got this error too what we did is ran vacuum analyze verbose and
afterthat reindexed the db and we din't see the error croping again.

Regards
Vidhya

On Thu, Apr 14, 2011 at 5:26 PM, Gipsz Jakab <clausewitz45(at)gmail(dot)com> wrote:

> Dear List,
>
> Today morning at 01:00 AM in our PostgreSQL 9.0.3 server a routine
> maintenance script has started (vacuumdb --all --full --analyze), and
> stopped with this error:
>
> sqlstate=23505ERROR: duplicate key value violates unique constraint
> "pg_index_indexrelid_index"
> sqlstate=23505DETAIL: Key (indexrelid)=(2678) already exists.
>
> We didn't do or change anything in postgre enviroment (except we raised the
> max_lock_per_transaction from 64 to 128)
>
> I've started a search on the internet, because of this error, but I didn't
> find anything, that I can use. Any idea? I've checked the postgres DB /
> catalogs / pg_catalog / tables / pg_index, and there is the record where
> indexrelid=2678, but there is only one record there...
>
> I saw, that somebody has the same problem (with the same ID!), and Tom Lane
> and Robert Haas requested the (select ctid,xmin,xmax,* from pg_index;) query
> output in a file. See attached.
>
> PostgreSQL: PostgreSQL 9.0.3 on i386-portbld-freebsd8.2, compiled by GCC
> cc (GCC) 4.2.1 20070719 [FreeBSD], 32-bit
>
> Thanks, and regards,
> Carl
>
>
> --
> Sent via pgsql-general mailing list (pgsql-general(at)postgresql(dot)org)
> To make changes to your subscription:
> http://www.postgresql.org/mailpref/pgsql-general
>
>


From: Carl von Clausewitz <clausewitz45(at)gmail(dot)com>
To: Vidhya Bondre <vbondre(at)zedo(dot)com>
Cc: pgsql-general(at)postgresql(dot)org
Subject: Re: Vacuumdb error
Date: 2011-04-14 13:16:44
Message-ID: BANLkTik1qzjJaxq_2yBSsCSQTmKTH_XFZQ@mail.gmail.com
Views: Raw Message | Whole Thread | Download mbox | Resend email
Lists: pgsql-general

Ok, thanks, I'll try at night.
Regards,
Carl

2011/4/14 Vidhya Bondre <vbondre(at)zedo(dot)com>

> Gipsz,
>
> We got this error too what we did is ran vacuum analyze verbose and
> afterthat reindexed the db and we din't see the error croping again.
>
> Regards
> Vidhya
>
> On Thu, Apr 14, 2011 at 5:26 PM, Gipsz Jakab <clausewitz45(at)gmail(dot)com>wrote:
>
>> Dear List,
>>
>> Today morning at 01:00 AM in our PostgreSQL 9.0.3 server a routine
>> maintenance script has started (vacuumdb --all --full --analyze), and
>> stopped with this error:
>>
>> sqlstate=23505ERROR: duplicate key value violates unique constraint
>> "pg_index_indexrelid_index"
>> sqlstate=23505DETAIL: Key (indexrelid)=(2678) already exists.
>>
>> We didn't do or change anything in postgre enviroment (except we raised
>> the max_lock_per_transaction from 64 to 128)
>>
>> I've started a search on the internet, because of this error, but I didn't
>> find anything, that I can use. Any idea? I've checked the postgres DB /
>> catalogs / pg_catalog / tables / pg_index, and there is the record where
>> indexrelid=2678, but there is only one record there...
>>
>> I saw, that somebody has the same problem (with the same ID!), and Tom
>> Lane and Robert Haas requested the (select ctid,xmin,xmax,* from pg_index;)
>> query output in a file. See attached.
>>
>> PostgreSQL: PostgreSQL 9.0.3 on i386-portbld-freebsd8.2, compiled by GCC
>> cc (GCC) 4.2.1 20070719 [FreeBSD], 32-bit
>>
>> Thanks, and regards,
>> Carl
>>
>>
>> --
>> Sent via pgsql-general mailing list (pgsql-general(at)postgresql(dot)org)
>> To make changes to your subscription:
>> http://www.postgresql.org/mailpref/pgsql-general
>>
>>
>


From: Tom Lane <tgl(at)sss(dot)pgh(dot)pa(dot)us>
To: Gipsz Jakab <clausewitz45(at)gmail(dot)com>
Cc: pgsql-general(at)postgresql(dot)org
Subject: Re: Vacuumdb error
Date: 2011-04-14 16:25:05
Message-ID: 15576.1302798305@sss.pgh.pa.us
Views: Raw Message | Whole Thread | Download mbox | Resend email
Lists: pgsql-general

Gipsz Jakab <clausewitz45(at)gmail(dot)com> writes:
> Today morning at 01:00 AM in our PostgreSQL 9.0.3 server a routine
> maintenance script has started (vacuumdb --all --full --analyze), and
> stopped with this error:

> sqlstate=23505ERROR: duplicate key value violates unique constraint
> "pg_index_indexrelid_index"
> sqlstate=23505DETAIL: Key (indexrelid)=(2678) already exists.

Maybe you had better show us *all* of your "routine maintenance" steps,
because there are some fairly unexplainable things in that pg_index dump.
VACUUM FULL alone wouldn't have resulted in the pg_index and pg_class
indexes' entries having updated xmins:

> "(1,40)";"48741";"0";2678;2610;1;false;false;true;false;true;false;true
> "(1,41)";"48741";"0";2679;2610;1;true;false;true;false;true;true;true
> "(1,42)";"49791";"0";2662;1259;1;true;false;true;false;true;true;true
> "(1,43)";"49791";"0";2663;1259;2;true;false;true;false;true;true;true

and I'm wondering how come three of them have indcheckxmin true too.
I think you must be whacking the system catalogs around harder than
you've admitted to.

regards, tom lane


From: Carl von Clausewitz <clausewitz45(at)gmail(dot)com>
To: Tom Lane <tgl(at)sss(dot)pgh(dot)pa(dot)us>
Cc: pgsql-general(at)postgresql(dot)org
Subject: Re: Vacuumdb error
Date: 2011-04-14 16:36:55
Message-ID: BANLkTin-dsQWj9ddyoWr6Y0JFL0iFT760A@mail.gmail.com
Views: Raw Message | Whole Thread | Download mbox | Resend email
Lists: pgsql-general

Hi,

see the two scripts attached. First one is the postgres_maintenance.sh, and
the second is the postgres_backup.sh. I've attached it, and copied, because
of the antivirus filters :-)

regards,
Carl

Maintenance:
#!/bin/sh
date >> /var/log/postgresql_maintenance.log
/usr/local/bin/reindexdb --all --username=cvc >>
/var/log/postgresql_maintenance.log
echo "Reindex done" >> /var/log/postgresql_maintenance.log
/usr/local/bin/vacuumdb --all --full --analyze --username=cvc >>
/var/log/postgresql_maintenance.log
echo "Vacuum done" >> /var/log/postgresql_maintenance.log

Backup:
#!/bin/sh
date >> /var/log/postgresql_backup.log
/usr/local/bin/pg_dump --create --file=/usr/NAS/mentesek/postgres/$(date
+%Y%m%d).backup --format=c --no-owner --username=cvc ktv_migracio_access
echo "Backup done" >> /var/log/postgresql_backup.log

2011/4/14 Tom Lane <tgl(at)sss(dot)pgh(dot)pa(dot)us>

> Gipsz Jakab <clausewitz45(at)gmail(dot)com> writes:
> > Today morning at 01:00 AM in our PostgreSQL 9.0.3 server a routine
> > maintenance script has started (vacuumdb --all --full --analyze), and
> > stopped with this error:
>
> > sqlstate=23505ERROR: duplicate key value violates unique constraint
> > "pg_index_indexrelid_index"
> > sqlstate=23505DETAIL: Key (indexrelid)=(2678) already exists.
>
> Maybe you had better show us *all* of your "routine maintenance" steps,
> because there are some fairly unexplainable things in that pg_index dump.
> VACUUM FULL alone wouldn't have resulted in the pg_index and pg_class
> indexes' entries having updated xmins:
>
> > "(1,40)";"48741";"0";2678;2610;1;false;false;true;false;true;false;true
> > "(1,41)";"48741";"0";2679;2610;1;true;false;true;false;true;true;true
> > "(1,42)";"49791";"0";2662;1259;1;true;false;true;false;true;true;true
> > "(1,43)";"49791";"0";2663;1259;2;true;false;true;false;true;true;true
>
> and I'm wondering how come three of them have indcheckxmin true too.
> I think you must be whacking the system catalogs around harder than
> you've admitted to.
>
> regards, tom lane
>

Attachment Content-Type Size
postgre_backup.sh application/x-sh 254 bytes
postgre_maintenance.sh application/x-sh 370 bytes

From: Tom Lane <tgl(at)sss(dot)pgh(dot)pa(dot)us>
To: Carl von Clausewitz <clausewitz45(at)gmail(dot)com>
Cc: pgsql-general(at)postgresql(dot)org
Subject: Re: Vacuumdb error
Date: 2011-04-14 16:46:15
Message-ID: 16734.1302799575@sss.pgh.pa.us
Views: Raw Message | Whole Thread | Download mbox | Resend email
Lists: pgsql-general

Carl von Clausewitz <clausewitz45(at)gmail(dot)com> writes:
> Maintenance:
> #!/bin/sh
> date >> /var/log/postgresql_maintenance.log
> /usr/local/bin/reindexdb --all --username=cvc >>
> /var/log/postgresql_maintenance.log
> echo "Reindex done" >> /var/log/postgresql_maintenance.log
> /usr/local/bin/vacuumdb --all --full --analyze --username=cvc >>
> /var/log/postgresql_maintenance.log
> echo "Vacuum done" >> /var/log/postgresql_maintenance.log

Just FYI, the reindex step is 100% useless if you're going to do a
vacuum full afterwards.

Before 9.0 there was some value in doing vacuum full and then reindex,
but none whatsoever in the other ordering. As of 9.0 there's just no
point at all in doing both. VACUUM FULL rebuilds the indexes anyway.

regards, tom lane


From: Carl von Clausewitz <clausewitz45(at)gmail(dot)com>
To: Tom Lane <tgl(at)sss(dot)pgh(dot)pa(dot)us>
Cc: pgsql-general(at)postgresql(dot)org
Subject: Re: Vacuumdb error
Date: 2011-04-14 16:52:17
Message-ID: BANLkTikJMeO_=TPM-1bzgBV-QjNJ=kJ7+A@mail.gmail.com
Views: Raw Message | Whole Thread | Download mbox | Resend email
Lists: pgsql-general

Ok thanks, the information. I've made the mistake, I will change the script,
but I will try, that Vidhya told me. Let me see, what will going on.

Regards,
Carl

2011/4/14 Tom Lane <tgl(at)sss(dot)pgh(dot)pa(dot)us>

> Carl von Clausewitz <clausewitz45(at)gmail(dot)com> writes:
> > Maintenance:
> > #!/bin/sh
> > date >> /var/log/postgresql_maintenance.log
> > /usr/local/bin/reindexdb --all --username=cvc >>
> > /var/log/postgresql_maintenance.log
> > echo "Reindex done" >> /var/log/postgresql_maintenance.log
> > /usr/local/bin/vacuumdb --all --full --analyze --username=cvc >>
> > /var/log/postgresql_maintenance.log
> > echo "Vacuum done" >> /var/log/postgresql_maintenance.log
>
> Just FYI, the reindex step is 100% useless if you're going to do a
> vacuum full afterwards.
>
> Before 9.0 there was some value in doing vacuum full and then reindex,
> but none whatsoever in the other ordering. As of 9.0 there's just no
> point at all in doing both. VACUUM FULL rebuilds the indexes anyway.
>
> regards, tom lane
>


From: Carl von Clausewitz <clausewitz45(at)gmail(dot)com>
To: Tom Lane <tgl(at)sss(dot)pgh(dot)pa(dot)us>
Cc: pgsql-general(at)postgresql(dot)org
Subject: Re: Vacuumdb error
Date: 2011-04-14 20:17:54
Message-ID: BANLkTi=1XnC5fHK078X1Wj5+-hcHkmC0xA@mail.gmail.com
Views: Raw Message | Whole Thread | Download mbox | Resend email
Lists: pgsql-general

Everything was fine, the reordered script fixed everything. Thanks all.

Regards,
Carl

2011/4/14 Carl von Clausewitz <clausewitz45(at)gmail(dot)com>

> Ok thanks, the information. I've made the mistake, I will change the
> script, but I will try, that Vidhya told me. Let me see, what will going
> on.
>
> Regards,
> Carl
>
> 2011/4/14 Tom Lane <tgl(at)sss(dot)pgh(dot)pa(dot)us>
>
>> Carl von Clausewitz <clausewitz45(at)gmail(dot)com> writes:
>> > Maintenance:
>> > #!/bin/sh
>> > date >> /var/log/postgresql_maintenance.log
>> > /usr/local/bin/reindexdb --all --username=cvc >>
>> > /var/log/postgresql_maintenance.log
>> > echo "Reindex done" >> /var/log/postgresql_maintenance.log
>> > /usr/local/bin/vacuumdb --all --full --analyze --username=cvc >>
>> > /var/log/postgresql_maintenance.log
>> > echo "Vacuum done" >> /var/log/postgresql_maintenance.log
>>
>> Just FYI, the reindex step is 100% useless if you're going to do a
>> vacuum full afterwards.
>>
>> Before 9.0 there was some value in doing vacuum full and then reindex,
>> but none whatsoever in the other ordering. As of 9.0 there's just no
>> point at all in doing both. VACUUM FULL rebuilds the indexes anyway.
>>
>> regards, tom lane
>>
>
>


From: Tom Lane <tgl(at)sss(dot)pgh(dot)pa(dot)us>
To: Carl von Clausewitz <clausewitz45(at)gmail(dot)com>
Cc: pgsql-general(at)postgresql(dot)org
Subject: Re: Vacuumdb error
Date: 2011-04-15 20:33:30
Message-ID: 426.1302899610@sss.pgh.pa.us
Views: Raw Message | Whole Thread | Download mbox | Resend email
Lists: pgsql-general

Carl von Clausewitz <clausewitz45(at)gmail(dot)com> writes:
>>> sqlstate=23505ERROR: duplicate key value violates unique constraint
>>> "pg_index_indexrelid_index"
>>> sqlstate=23505DETAIL: Key (indexrelid)=(2678) already exists.

After a considerable amount of fooling around I've been able to
reproduce this and identify the cause:
http://archives.postgresql.org/pgsql-hackers/2011-04/msg00777.php

A real fix will be forthcoming in the next update releases (not Monday's
updates, unfortunately; too late for that). In the meantime, it appears
that the problem can only be triggered by a sequence that involves
*both* REINDEX and VACUUM FULL on pg_index. Since, as I mentioned
before, a separate reindex step is completely useless when using 9.0's
VACUUM FULL, removing the reindex step from your maintenance script
should be an adequate workaround.

regards, tom lane