Обсуждение: vacuum deadlock

Поиск
Список
Период
Сортировка

vacuum deadlock

От
Ibrahim Harrani
Дата:
Hi,

I am using PostgreSQL 8.3.7.
autovacuum is enabled in postgresql.conf

I got  a deadlock while vacuuming all databases with vacuumdb command.

vacuumdb: vacuuming of database "mydb" failed: ERROR:  deadlock detected
DETAIL:  Process 1294 waits for AccessExclusiveLock on relation 2662 of database     ; blocked by process 1807.
Process 1807 waits for AccessShareLock on relation 1259 of database 16389; blocked by process 1294.

I think, because of this lock, deleting a large table (15 million records) was taking too much time
How can I know the name of the relations 2662 and 1259?

Do you have any ide about the problem and solution?


Thanks in advance.

Re: vacuum deadlock

От
Yeb Havinga
Дата:
Ibrahim Harrani wrote:
> Hi,
>
> I am using PostgreSQL 8.3.7.
> autovacuum is enabled in postgresql.conf
>
> I got  a deadlock while vacuuming all databases with vacuumdb command.
>
> vacuumdb: vacuuming of database "mydb" failed: ERROR:  deadlock detected
> DETAIL:  Process 1294 waits for AccessExclusiveLock on relation 2662
> of database     ; blocked by process 1807.
> Process 1807 waits for AccessShareLock on relation 1259 of database
> 16389; blocked by process 1294.
>
> I think, because of this lock, deleting a large table (15 million
> records) was taking too much time
> How can I know the name of the relations 2662 and 1259?
postgres=# select oid,relname from pg_class where oid in (2662,1259);
 oid  |      relname
------+--------------------
 2662 | pg_class_oid_index
 1259 | pg_class
(2 rows)
> Do you have any ide about the problem and solution?
It would be interesting to know what are the processes 1807 and 1294.
Once that is known, try to avoid executing both processes concurrently.

regards
Yeb Havinga


Re: vacuum deadlock

От
Ibrahim Harrani
Дата:
Hi Yeb,

Thanks for your reply.
As far as I know, pg_class_oid_index and pg_class are postgresql internal relations.

Normally, there is not application that directly using those relations.
How should I map this lock issue on this relations to my application side?
On which cases those are locked and used by applications?


Thanks

On Fri, Feb 5, 2010 at 2:36 PM, Yeb Havinga <yebhavinga@gmail.com> wrote:
Ibrahim Harrani wrote:
Hi,

I am using PostgreSQL 8.3.7.
autovacuum is enabled in postgresql.conf

I got  a deadlock while vacuuming all databases with vacuumdb command.

vacuumdb: vacuuming of database "mydb" failed: ERROR:  deadlock detected
DETAIL:  Process 1294 waits for AccessExclusiveLock on relation 2662 of database     ; blocked by process 1807.
Process 1807 waits for AccessShareLock on relation 1259 of database 16389; blocked by process 1294.

I think, because of this lock, deleting a large table (15 million records) was taking too much time
How can I know the name of the relations 2662 and 1259?
postgres=# select oid,relname from pg_class where oid in (2662,1259);
oid  |      relname      ------+--------------------
2662 | pg_class_oid_index
1259 | pg_class
(2 rows)

Do you have any ide about the problem and solution?
It would be interesting to know what are the processes 1807 and 1294. Once that is known, try to avoid executing both processes concurrently.

regards
Yeb Havinga


Re: vacuum deadlock

От
"Kevin Grittner"
Дата:
Ibrahim Harrani <ibrahim.harrani@gmail.com> wrote:
> Yeb Havinga <yebhavinga@gmail.com> wrote:
>> Ibrahim Harrani wrote:

>>> I am using PostgreSQL 8.3.7.
>>> autovacuum is enabled in postgresql.conf
>>>
>>> I got  a deadlock while vacuuming all databases with vacuumdb
>>> command.
>>>
>>> vacuumdb: vacuuming of database "mydb" failed: ERROR:  deadlock
>>> detected
>>> DETAIL:  Process 1294 waits for AccessExclusiveLock on relation
>>> 2662 of database     ; blocked by process 1807.
>>> Process 1807 waits for AccessShareLock on relation 1259 of
>>> database 16389; blocked by process 1294.
>>>
>>> I think, because of this lock, deleting a large table (15
>>> million records) was taking too much time
>>> How can I know the name of the relations 2662 and 1259?
>>>
>> postgres=# select oid,relname from pg_class where oid in
>> (2662,1259);
>> oid  |      relname      ------+--------------------
>> 2662 | pg_class_oid_index
>> 1259 | pg_class
>> (2 rows)

> As far as I know, pg_class_oid_index and pg_class are postgresql
> internal relations.
>
> Normally, there is not application that directly using those
> relations.
> How should I map this lock issue on this relations to my
> application side?
> On which cases those are locked and used by applications?

Are you creating temporary tables somehow during this process, like
within functions (including trigger functions)?

Can you test the delete with autovacuum disabled?

When you say "deleting a large table" do you mean, dropping the
table, deleting all rows from the table, or deleting some of the
rows from the table?

If you could show the actual delete statement and all information
about the table(s) involved, including indexes, triggers, and
foreign keys, that might help.

-Kevin

Re: vacuum deadlock

От
Tom Lane
Дата:
Ibrahim Harrani <ibrahim.harrani@gmail.com> writes:
> I got  a deadlock while vacuuming all databases with vacuumdb command.

> vacuumdb: vacuuming of database "mydb" failed: ERROR:  deadlock detected
> DETAIL:  Process 1294 waits for AccessExclusiveLock on relation 2662 of
> database     ; blocked by process 1807.
> Process 1807 waits for AccessShareLock on relation 1259 of database 16389;
> blocked by process 1294.

vacuumdb -f you mean?  An ordinary vacuum wouldn't be trying to take
AccessExclusiveLock.

It might be that you have an instance of a failure that was identified
just a couple weeks ago:
http://archives.postgresql.org/pgsql-committers/2010-01/msg00199.php

            regards, tom lane

Re: vacuum deadlock

От
Ibrahim Harrani
Дата:
Hi,

Yes,  I am trying to full vacuum.

I think, I  found the problem. There were more then 10 million records which my scripts trying to delete at night from a table while other processes were adding new entries to same table.
Delete can't finish in the day, and script tries to delete the table again in next night via crontab
then this cause to dead lock?

SQL query: "delete from mytable where createtime < now - '10 days';


We added 1K limit option to delete query in a for loop. Now I can delete all entries but slowly 

DELETE FROM mytable WHERE id = any (array(SELECT id FROM mytable WHERE createtime < NOW() - INTERVAL '10 day'  LIMIT 1000))

I am planning to partion(day based) this large table, then I will simply drop the tables after certain days.

Do you have any other suggestion?

Thanks.

On Sat, Feb 6, 2010 at 8:11 AM, Tom Lane <tgl@sss.pgh.pa.us> wrote:
Ibrahim Harrani <ibrahim.harrani@gmail.com> writes:
> I got  a deadlock while vacuuming all databases with vacuumdb command.

> vacuumdb: vacuuming of database "mydb" failed: ERROR:  deadlock detected
> DETAIL:  Process 1294 waits for AccessExclusiveLock on relation 2662 of
> database     ; blocked by process 1807.
> Process 1807 waits for AccessShareLock on relation 1259 of database 16389;
> blocked by process 1294.

vacuumdb -f you mean?  An ordinary vacuum wouldn't be trying to take
AccessExclusiveLock.

It might be that you have an instance of a failure that was identified
just a couple weeks ago:
http://archives.postgresql.org/pgsql-committers/2010-01/msg00199.php

                       regards, tom lane