Re: slow queue-like empty table

From: Csaba Nagy <nagy(at)ecircle-ag(dot)com>
To: Tobias Brox <tobias(at)nordicbet(dot)com>
Cc: postgres performance list <pgsql-performance(at)postgresql(dot)org>
Subject: Re: slow queue-like empty table
Date: 2006-09-28 08:45:35
Message-ID: 1159433135.3874.204.camel@coppola.muc.ecircle.de
Views: Raw Message | Whole Thread | Download mbox | Resend email
Thread:
Lists: pgsql-performance

On Thu, 2006-09-28 at 09:36, Tobias Brox wrote:
> [Tobias Brox - Thu at 08:56:31AM +0200]
> > It really seems like some transaction is still viewing the queue, since
> > it found 38k of non-removable rows ... but how do I find the pid of the
> > transaction viewing the queue? As said, the pg_locks didn't give me any
> > hints ...

The open transaction doesn't have to have any locks on your queue table
to prevent vacuuming dead rows. It's mere existence is enough... MVCC
means that a still running transaction could still see those dead rows,
and so VACUUM can't remove them until there's no transaction which
started before they were deleted.

So long running transactions are your enemy when it comes to high
insert/delete rate queue tables.

So you should check for "idle in transaction" sessions, those are bad...
or any other long running transaction.

> Dropping the table and recreating it solved the immediate problem, but
> there must be some better solution than that? :-)

If you must have long running transactions on your system (like
vacuuming another big table - that also qualifies as a long running
transaction, though this is fixed in 8.2), then you could use CLUSTER
(see the docs), which is currently not MVCC conforming and deletes all
the dead space regardless if any other running transaction can see it or
not. This is only acceptable if you're application handles the queue
table independently, not mixed in complex transactions. And the CLUSTER
command takes an exclusive lock on the table, so it won't work for e.g.
during a pg_dump, it would keep the queue table locked exclusively for
the whole duration of the pg_dump (it won't be able to actually get the
lock, but it will prevent any other activity on it, as it looks like in
progress exclusive lock requests block any new shared lock request).

HTH,
Csaba.

In response to

Responses

Browse pgsql-performance by date

  From Date Subject
Next Message Jignesh K. Shah 2006-09-28 12:35:36 Re: slow i/o
Previous Message Edoardo Ceccarelli 2006-09-28 08:44:05 Re: autovacuum on a -mostly- r/o table