Thread: VACUUM and transactions in different databases

VACUUM and transactions in different databases

From
Cornelia Boenigk
Date:
Hi all

If I have a running transaction in database1 and try to vacuum database2
but the dead tuples in database2 cannot be removed.

INFO:  vacuuming "public.dummy1"
INFO:  "dummy1": found 0 removable, 140000 nonremovable row versions in
1341 pages
DETAIL:  135000 dead row versions cannot be removed yet.

How can I achieve that database2 is vacuumed while a transaction in
database1 is not yet commited?

Regards
conni

Re: VACUUM and transactions in different databases

From
Bill Moran
Date:
Cornelia Boenigk <c@cornelia-boenigk.de> wrote:
>
> Hi all
>
> If I have a running transaction in database1 and try to vacuum database2
> but the dead tuples in database2 cannot be removed.
>
> INFO:  vacuuming "public.dummy1"
> INFO:  "dummy1": found 0 removable, 140000 nonremovable row versions in
> 1341 pages
> DETAIL:  135000 dead row versions cannot be removed yet.
>
> How can I achieve that database2 is vacuumed while a transaction in
> database1 is not yet commited?

I don't believe that's the reason.  AFAIK, activity in one database will
never block activity in another.

I would suspect that you haven't vacuumed this database in a long time,
and an ordinary vacuum can't reclaim that space.  Can you run a "vacuum
full", and does it reclaim the space?  If you do regular vacuum often
enough, you should never end up with so much unused space, unless your
usage pattern is very drastic, in which case you should look at other
methods of managing that table -- perhaps CLUSTER.

-Bill

Re: VACUUM and transactions in different databases

From
Cornelia Boenigk
Date:
Hi Bill

 > I don't believe that's the reason.  AFAIK, activity in one database
 > will never block activity in another.

This way I read the documentation.

 > I would suspect that you haven't vacuumed this database in a long time,

I created both databases one hour ago for just testing this behaviour. I
started with two identical tables, each with 5000 rows in both
databases. In db1 I opened a transaction, updated the table and left the
transaction open.

In db2 I updated, inserted and deleted a lot and then tried to vacuum.

 > Can you run a "vacuum
 > full", and does it reclaim the space?

I tried but it hangs.

[root@conni ~]# ps axw|grep postgres
  1746 ?        S      0:00 postgres: writer process
  1747 ?        S      0:00 postgres: stats buffer process
  1748 ?        S      0:00 postgres: stats collector process
  2106 pts/1    S      0:00 su postgres
  2120 pts/1    S+     0:00 psql postgres
  2188 ?        S      0:04 postgres: postgres dummy1 [local] VACUUM waiting
  2200 pts/3    S      0:00 su postgres
  2215 ?        S      0:00 postgres: postgres dummy2 [local] idle in
transaction
  2717 pts/2    R+     0:00 grep postgres

Regards
Conni

Re: VACUUM and transactions in different databases

From
Cornelia Boenigk
Date:
Hi

as soon as I committed the open transaction the hangig vacuum full
completed and the table was vacuumed:

regards
Conni

Re: VACUUM and transactions in different databases

From
Bill Moran
Date:
Cornelia Boenigk <c@cornelia-boenigk.de> wrote:
>
> Hi Bill
>
>  > I don't believe that's the reason.  AFAIK, activity in one database
>  > will never block activity in another.
>
> This way I read the documentation.

psql -U pgsql db2
Welcome to psql 8.2.0, the PostgreSQL interactive terminal.

Type:  \copyright for distribution terms
       \h for help with SQL commands
       \? for help with psql commands
       \g or terminate with semicolon to execute query
       \q to quit

psql -U pgsql db1
Welcome to psql 8.2.0, the PostgreSQL interactive terminal.

Type:  \copyright for distribution terms
       \h for help with SQL commands
       \? for help with psql commands
       \g or terminate with semicolon to execute query
       \q to quit

db1=# begin;
BEGIN
db1=# insert into t1 values (44, 'text string');
INSERT 0 1
db1=#
[1]+  Stopped                 psql -U pgsql db1
[wmoran@working ~]$ psql -U pgsql db2
Welcome to psql 8.2.0, the PostgreSQL interactive terminal.

Type:  \copyright for distribution terms
       \h for help with SQL commands
       \? for help with psql commands
       \g or terminate with semicolon to execute query
       \q to quit

db2=# vacuum full;
VACUUM
db2=# \q
[wmoran@working ~]$ fg
psql -U pgsql db1
rollback;
ROLLBACK

Works that way for me ...

>  > I would suspect that you haven't vacuumed this database in a long time,
>
> I created both databases one hour ago for just testing this behaviour. I
> started with two identical tables, each with 5000 rows in both
> databases. In db1 I opened a transaction, updated the table and left the
> transaction open.
>
> In db2 I updated, inserted and deleted a lot and then tried to vacuum.

So, long time then.  My definition of "long time" is equal to your
definition of "a lot" :)

>  > Can you run a "vacuum
>  > full", and does it reclaim the space?
>
> I tried but it hangs.
>
> [root@conni ~]# ps axw|grep postgres
>   1746 ?        S      0:00 postgres: writer process
>   1747 ?        S      0:00 postgres: stats buffer process
>   1748 ?        S      0:00 postgres: stats collector process
>   2106 pts/1    S      0:00 su postgres
>   2120 pts/1    S+     0:00 psql postgres
>   2188 ?        S      0:04 postgres: postgres dummy1 [local] VACUUM waiting
>   2200 pts/3    S      0:00 su postgres
>   2215 ?        S      0:00 postgres: postgres dummy2 [local] idle in
> transaction
>   2717 pts/2    R+     0:00 grep postgres

You might want to provide some more details on what you're doing.
Obviously, the simplified version of your problem doesn't exist (as
demonstrated by the fact that I can't reproduce it).  Perhaps your
transaction is doing something different that what you expect.

-Bill

Re: VACUUM and transactions in different databases

From
Christopher Browne
Date:
Oops! c@cornelia-boenigk.de (Cornelia Boenigk) was seen spray-painting on a wall:
> Hi all
>
> If I have a running transaction in database1 and try to vacuum
> database2 but the dead tuples in database2 cannot be removed.
>
> INFO:  vacuuming "public.dummy1"
> INFO:  "dummy1": found 0 removable, 140000 nonremovable row versions
> in 1341 pages
> DETAIL:  135000 dead row versions cannot be removed yet.
>
> How can I achieve that database2 is vacuumed while a transaction in
> database1 is not yet commited?

You can't, unless you're on 8.1, and the not-yet-committed transaction
is VACUUM.

You have discovered a known factor, that a transaction left open on
one database may have adverse effects on another database.
--
(format nil "~S@~S" "cbbrowne" "acm.org")
http://linuxdatabases.info/info/rdbms.html
Signs of a Klingon  Programmer #4:  "A  TRUE Klingon Warrior  does not
comment his code!"

Re: VACUUM and transactions in different databases

From
Bill Moran
Date:
In response to Christopher Browne <cbbrowne@acm.org>:
> Oops! c@cornelia-boenigk.de (Cornelia Boenigk) was seen spray-painting on a wall:
> > Hi all
> >
> > If I have a running transaction in database1 and try to vacuum
> > database2 but the dead tuples in database2 cannot be removed.
> >
> > INFO:  vacuuming "public.dummy1"
> > INFO:  "dummy1": found 0 removable, 140000 nonremovable row versions
> > in 1341 pages
> > DETAIL:  135000 dead row versions cannot be removed yet.
> >
> > How can I achieve that database2 is vacuumed while a transaction in
> > database1 is not yet commited?
>
> You can't, unless you're on 8.1, and the not-yet-committed transaction
> is VACUUM.

I'm a little confused.

First off, it would seem as if this is completely eliminated in 8.2, as
I tested a scenario involving an idle transaction in one database, and
both vacuum and vacuum full were able to complete in another database
without completing the first transaction.

Are you saying that in 8.1, there is a single exception to this, which
is that if db1 (for example) is in the process of running vacuum, it
won't block db2 from vacuuming?  But that any other type of transaction
can block operations in other databases?

--
Bill Moran
Collaborative Fusion Inc.

Re: VACUUM and transactions in different databases

From
Alvaro Herrera
Date:
Bill Moran wrote:
> In response to Christopher Browne <cbbrowne@acm.org>:
> > Oops! c@cornelia-boenigk.de (Cornelia Boenigk) was seen spray-painting on a wall:
> > > Hi all
> > >
> > > If I have a running transaction in database1 and try to vacuum
> > > database2 but the dead tuples in database2 cannot be removed.
> > >
> > > INFO:  vacuuming "public.dummy1"
> > > INFO:  "dummy1": found 0 removable, 140000 nonremovable row versions
> > > in 1341 pages
> > > DETAIL:  135000 dead row versions cannot be removed yet.
> > >
> > > How can I achieve that database2 is vacuumed while a transaction in
> > > database1 is not yet commited?
> >
> > You can't, unless you're on 8.1, and the not-yet-committed transaction
> > is VACUUM.
>
> I'm a little confused.
>
> First off, it would seem as if this is completely eliminated in 8.2, as
> I tested a scenario involving an idle transaction in one database, and
> both vacuum and vacuum full were able to complete in another database
> without completing the first transaction.

Of course they are able to complete, but the point is that they would
not remove the tuples that would be visible to that idle open
transaction.

> Are you saying that in 8.1, there is a single exception to this, which
> is that if db1 (for example) is in the process of running vacuum, it
> won't block db2 from vacuuming?  But that any other type of transaction
> can block operations in other databases?

In 8.2, a process running lazy vacuum (but not vacuum full) will not
interfere with another process running vacuum, i.e., the second vacuum
will be able to remove the tuples even if they would be seen by the
transaction doing the first vacuum -- regardless of the database to
which any of them is connected (i.e., it may be the same database or
different databases).  I don't remember if this was in 8.1 or was
introduced in 8.2.

--
Alvaro Herrera                                http://www.CommandPrompt.com/
PostgreSQL Replication, Consulting, Custom Development, 24x7 support

Re: VACUUM and transactions in different databases

From
Bill Moran
Date:
In response to Alvaro Herrera <alvherre@commandprompt.com>:

> Bill Moran wrote:
> > In response to Christopher Browne <cbbrowne@acm.org>:
> > > Oops! c@cornelia-boenigk.de (Cornelia Boenigk) was seen spray-painting on a wall:
> > > > Hi all
> > > >
> > > > If I have a running transaction in database1 and try to vacuum
> > > > database2 but the dead tuples in database2 cannot be removed.
> > > >
> > > > INFO:  vacuuming "public.dummy1"
> > > > INFO:  "dummy1": found 0 removable, 140000 nonremovable row versions
> > > > in 1341 pages
> > > > DETAIL:  135000 dead row versions cannot be removed yet.
> > > >
> > > > How can I achieve that database2 is vacuumed while a transaction in
> > > > database1 is not yet commited?
> > >
> > > You can't, unless you're on 8.1, and the not-yet-committed transaction
> > > is VACUUM.
> >
> > I'm a little confused.
> >
> > First off, it would seem as if this is completely eliminated in 8.2, as
> > I tested a scenario involving an idle transaction in one database, and
> > both vacuum and vacuum full were able to complete in another database
> > without completing the first transaction.
>
> Of course they are able to complete, but the point is that they would
> not remove the tuples that would be visible to that idle open
> transaction.

I would expect that, but the OP claimed that vacuum full waited until
the other transaction was finished.

> > Are you saying that in 8.1, there is a single exception to this, which
> > is that if db1 (for example) is in the process of running vacuum, it
> > won't block db2 from vacuuming?  But that any other type of transaction
> > can block operations in other databases?
>
> In 8.2, a process running lazy vacuum (but not vacuum full) will not
> interfere with another process running vacuum, i.e., the second vacuum
> will be able to remove the tuples even if they would be seen by the
> transaction doing the first vacuum -- regardless of the database to
> which any of them is connected (i.e., it may be the same database or
> different databases).  I don't remember if this was in 8.1 or was
> introduced in 8.2.

So lazy vacuum never waits on transactions.  Apparently (based on the
OP) vacuum full _does_ wait on transactions in versions prior to 8.2,
but based on my experiment, in 8.2 vacuum full no longer does.

Of course, in any version, vacuum can't clean up tuples held by open
transactions.

At least, that's what it's looking like to me.

--
Bill Moran
Collaborative Fusion Inc.

wmoran@collaborativefusion.com
Phone: 412-422-3463x4023

****************************************************************
IMPORTANT: This message contains confidential information and is
intended only for the individual named. If the reader of this
message is not an intended recipient (or the individual
responsible for the delivery of this message to an intended
recipient), please be advised that any re-use, dissemination,
distribution or copying of this message is prohibited. Please
notify the sender immediately by e-mail if you have received
this e-mail by mistake and delete this e-mail from your system.
E-mail transmission cannot be guaranteed to be secure or
error-free as information could be intercepted, corrupted, lost,
destroyed, arrive late or incomplete, or contain viruses. The
sender therefore does not accept liability for any errors or
omissions in the contents of this message, which arise as a
result of e-mail transmission.
****************************************************************

Re: VACUUM and transactions in different databases

From
Tom Lane
Date:
Bill Moran <wmoran@collaborativefusion.com> writes:
> In response to Alvaro Herrera <alvherre@commandprompt.com>:
>> Of course they are able to complete, but the point is that they would
>> not remove the tuples that would be visible to that idle open
>> transaction.

> I would expect that, but the OP claimed that vacuum full waited until
> the other transaction was finished.

No, she didn't claim that.  As far as I see she was just complaining
about the failure to remove dead tuples:

> > > > If I have a running transaction in database1 and try to vacuum
> > > > database2 but the dead tuples in database2 cannot be removed.

            regards, tom lane

Re: VACUUM and transactions in different databases

From
Ragnar
Date:
On fim, 2006-12-07 at 11:28 -0500, Tom Lane wrote:
> Bill Moran <wmoran@collaborativefusion.com> writes:
> > In response to Alvaro Herrera <alvherre@commandprompt.com>:
> >> Of course they are able to complete, but the point is that they would
> >> not remove the tuples that would be visible to that idle open
> >> transaction.
>
> > I would expect that, but the OP claimed that vacuum full waited until
> > the other transaction was finished.
>
> No, she didn't claim that.  As far as I see she was just complaining
> about the failure to remove dead tuples:
>
> > > > > If I have a running transaction in database1 and try to vacuum
> > > > > database2 but the dead tuples in database2 cannot be removed.

well actually, there was also this:

On fim, 2006-12-07 at 00:57 +0100, Cornelia Boenigk wrote:
> Hi Bill
>
>  > Can you run a "vacuum
>  > full", and does it reclaim the space?
>
> I tried but it hangs.

and also this:

On fim, 2006-12-07 at 01:03 +0100, Cornelia Boenigk wrote:
>
> as soon as I committed the open transaction the hangig vacuum full
> completed and the table was vacuumed:

gnari




Re: VACUUM and transactions in different databases

From
Bill Moran
Date:
In response to Tom Lane <tgl@sss.pgh.pa.us>:

> Bill Moran <wmoran@collaborativefusion.com> writes:
> > In response to Alvaro Herrera <alvherre@commandprompt.com>:
> >> Of course they are able to complete, but the point is that they would
> >> not remove the tuples that would be visible to that idle open
> >> transaction.
>
> > I would expect that, but the OP claimed that vacuum full waited until
> > the other transaction was finished.
>
> No, she didn't claim that.  As far as I see she was just complaining
> about the failure to remove dead tuples:
>
> > > > > If I have a running transaction in database1 and try to vacuum
> > > > > database2 but the dead tuples in database2 cannot be removed.

Yes, but a later mail in the thread read:

> > Can you run a "vacuum
> > full", and does it reclaim the space?
>
> I tried but it hangs.
>
> [root@conni ~]# ps axw|grep postgres
>  1746 ?        S      0:00 postgres: writer process
>  1747 ?        S      0:00 postgres: stats buffer process
>  1748 ?        S      0:00 postgres: stats collector process
>  2106 pts/1    S      0:00 su postgres
>  2120 pts/1    S+     0:00 psql postgres
>  2188 ?        S      0:04 postgres: postgres dummy1 [local] VACUUM waiting
>  2200 pts/3    S      0:00 su postgres
>  2215 ?        S      0:00 postgres: postgres dummy2 [local] idle in transaction
>  2717 pts/2    R+     0:00 grep postgres

Admittedly, I had the (incorrect) idea that she might need a vacuum
full to reclaim space that lazy vacuum couldn't.  And, admittedly, this
wasn't the point of the original post.

--
Bill Moran
Collaborative Fusion Inc.

Re: VACUUM and transactions in different databases

From
Tom Lane
Date:
Bill Moran <wmoran@collaborativefusion.com> writes:
>> [root@conni ~]# ps axw|grep postgres
>> 1746 ?        S      0:00 postgres: writer process
>> 1747 ?        S      0:00 postgres: stats buffer process
>> 1748 ?        S      0:00 postgres: stats collector process
>> 2106 pts/1    S      0:00 su postgres
>> 2120 pts/1    S+     0:00 psql postgres
>> 2188 ?        S      0:04 postgres: postgres dummy1 [local] VACUUM waiting
>> 2200 pts/3    S      0:00 su postgres
>> 2215 ?        S      0:00 postgres: postgres dummy2 [local] idle in transaction
>> 2717 pts/2    R+     0:00 grep postgres

Too bad this wasn't accompanied by a dump of pg_locks ... but if that's
the only other open transaction, the only way I can see for it to block
the vacuum is if the vacuum was database-wide, and had gotten to the
point of trying to vacuum one of the shared catalogs (eg, pg_database),
and the other transaction had some type of lock on that shared catalog.

            regards, tom lane

Re: VACUUM and transactions in different databases

From
Cornelia Boenigk
Date:
Hi

Sorry, i was out

The first try was:

create database dummy1;
create table dummy ... and filled with 500 records

create database dummy2;
create table dummy ... and filled with 500 records


connecting to dummy1, opening a transaction and issued an update

begin;
update dummy set f1='achterbahn';


then opened a second console and connected to dummy2:

dummy2=# select count(*) from dummy;
  count
-------
   5000
(1 row)

dummy2=# SELECT relpages, reltuples FROM pg_class WHERE relname ='dummy';
  relpages | reltuples
----------+-----------
       160 |      5000
(1 row)

updated the table several times - to generate dead tuples:

dummy2=# SELECT relpages, reltuples FROM pg_class WHERE relname ='dummy';
  relpages | reltuples
----------+-----------
       326 |     30000
(1 row)

dummy2=# vacuum;
VACUUM
dummy2=# SELECT relpages, reltuples FROM pg_class WHERE relname ='dummy';
  relpages | reltuples
----------+-----------
       326 |     30000
(1 row)

dummy2=# select count(*) from dummy;
  count
-------
   5000
(1 row)

dummy2=# vacuum full;
--------------------------------
vacuum was in waiting state as long the transaction in dummy1 was
opened. After committing the transaction the vacuum full was carried out.
-------------------------------
VACUUM

dummy2=# SELECT relpages, reltuples FROM pg_class WHERE relname ='dummy';
  relpages | reltuples
----------+-----------
       326 |     30000
(1 row)


running on pg 8.1.4 on Fedora 5

Thanks
Conni

Re: VACUUM and transactions in different databases

From
Ragnar
Date:
On fim, 2006-12-07 at 20:04 +0100, Cornelia Boenigk wrote:
> Sorry, i was out
>
> [ snip demonstration of blocked vacuum full]

> running on pg 8.1.4 on Fedora 5

could not duplicate this.

can you show us the contents of pg_locks and
pg_stat_activity while the VACUUM is blocked?

gnari



Re: VACUUM and transactions in different databases

From
Cornelia Boenigk
Date:
Hi Ragnar

> could not duplicate this.

I also cannot reproduce the hanging VACUUM FULL.
The problem remains thet the dead tuples cannot be vemoved.

dummy1=# vacuum full;
VACUUM
dummy1=# SELECT relpages, reltuples FROM pg_class WHERE relname ='dummy1';
-[ RECORD 1 ]-----
relpages  | 997
reltuples | 100000

dummy1=# analyze verbose;
...
INFO:  analyzing "public.dummy1"
INFO:  "dummy1": scanned 997 of 997 pages, containing 5000 live rows and 95000 dead rows; 3000 rows in sample, 5000
estimatedtotal rows 
...


dummy1=# select * from pg_stat_activity;
-[ RECORD 1 ]-+------------------------------
datid         | 21529
datname       | dummy1
procpid       | 2065
usesysid      | 10
usename       | postgres
current_query | <command string not enabled>
query_start   |
backend_start | 2006-12-07 21:03:54.877779+01
client_addr   |
client_port   | -1
-[ RECORD 2 ]-+------------------------------
datid         | 21530
datname       | dummy2
procpid       | 2152
usesysid      | 10
usename       | postgres
current_query | <command string not enabled>
query_start   |
backend_start | 2006-12-07 21:07:59.973477+01
client_addr   |
client_port   | -1

the transaction in db dummy2 performed an update and select count(*) and is still running.


dummy1=# select * from pg_locks;
-[ RECORD 1 ]-+-----------------
locktype      | relation
database      | 21530
relation      | 21540
page          |
tuple         |
transactionid |
classid       |
objid         |
objsubid      |
transaction   | 85385
pid           | 2152
mode          | AccessShareLock
granted       | t
-[ RECORD 2 ]-+-----------------
locktype      | relation
database      | 21530
relation      | 21540
page          |
tuple         |
transactionid |
classid       |
objid         |
objsubid      |
transaction   | 85385
pid           | 2152
mode          | RowExclusiveLock
granted       | t
-[ RECORD 3 ]-+-----------------
locktype      | relation
database      | 21529
relation      | 10342
page          |
tuple         |
transactionid |
classid       |
objid         |
objsubid      |
transaction   | 85925
pid           | 2065
mode          | AccessShareLock
granted       | t
-[ RECORD 4 ]-+-----------------
locktype      | transactionid
database      |
relation      |
page          |
tuple         |
transactionid | 85925
classid       |
objid         |
objsubid      |
transaction   | 85925
pid           | 2065
mode          | ExclusiveLock
granted       | t
-[ RECORD 5 ]-+-----------------
locktype      | transactionid
database      |
relation      |
page          |
tuple         |
transactionid | 85385
classid       |
objid         |
objsubid      |
transaction   | 85385
pid           | 2152
mode          | ExclusiveLock
granted       | t

Thanks
Conni


Re: VACUUM and transactions in different databases

From
Russell Smith
Date:
Cornelia Boenigk wrote:
> Hi Ragnar
>
>> could not duplicate this.
>
> I also cannot reproduce the hanging VACUUM FULL. The problem remains
> thet the dead tuples cannot be vemoved.
>
[snip]


I am interested in this. As one database cannot talk to another database
in a transactional way a long running transaction in one database should
not effect the vacuuming of another database.  From my limited
understanding VACUUM takes the lowest open transaction number and only
cleans up transactions with TID's lower than that.  The reason I believe
that it has to use cluster wide is because the shared catalogs might be
effected.  Do shared catalogs follow MVCC or ACID strictly? I don't
know, but I assume they don't follow both given my reading of the list.

So if shared catalogs are the problem, what happens if you just vacuum
the relevant table public.dummy1 and not the whole database, does the
vacuum remove all the tuples that are dead?

Is it possible to add logic for lazy vacuum that takes the lowest TID in
our database when not vacuuming shared catalogs?  This may already be
the case, I don't know.  Just putting forward suggestions.

Russell Smith