Обсуждение: Vacuum Full + Cluster + Vacuum full = non removable dead rows

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

Vacuum Full + Cluster + Vacuum full = non removable dead rows

От
Alexandre de Arruda Paes
Дата:
Hi,

PG 8.4.4

I have an strange problem:

carmen=# VACUUM FULL verbose tp93t;
INFO:  vacuuming "public.tp93t"
INFO:  "tp93t": found 0 removable, 71984 nonremovable row versions in 17996 pages
DETAIL:  70632 dead row versions cannot be removed yet.
Nonremovable row versions range from 1848 to 2032 bytes long.
There were 0 unused item pointers.
Total free space (including removable row versions) is 1523648 bytes.
0 pages are or will become empty, including 0 at the end of the table.
0 pages containing 0 free bytes are potential move destinations.
CPU 0.00s/0.03u sec elapsed 0.03 sec.
INFO:  index "tp93t_pkey" now contains 71984 row versions in 868 pages
DETAIL:  0 index pages have been deleted, 0 are currently reusable.
CPU 0.00s/0.00u sec elapsed 0.00 sec.
INFO:  vacuuming "pg_toast.pg_toast_24274"
INFO:  "pg_toast_24274": found 0 removable, 0 nonremovable row versions in 0 pages
DETAIL:  0 dead row versions cannot be removed yet.
Nonremovable row versions range from 0 to 0 bytes long.
There were 0 unused item pointers.
Total free space (including removable row versions) is 0 bytes.
0 pages are or will become empty, including 0 at the end of the table.
0 pages containing 0 free bytes are potential move destinations.
CPU 0.00s/0.00u sec elapsed 0.00 sec.
INFO:  index "pg_toast_24274_index" now contains 0 row versions in 1 pages
DETAIL:  0 index pages have been deleted, 0 are currently reusable.
CPU 0.00s/0.00u sec elapsed 0.00 sec.
VACUUM

armen=# cluster tp93t;
CLUSTER

carmen=# VACUUM FULL verbose tp93t;
INFO:  vacuuming "public.tp93t"
INFO:  "tp93t": found 0 removable, 71984 nonremovable row versions in 17996 pages
DETAIL:  70632 dead row versions cannot be removed yet.
Nonremovable row versions range from 1848 to 2032 bytes long.
There were 0 unused item pointers.
Total free space (including removable row versions) is 1523648 bytes.
0 pages are or will become empty, including 0 at the end of the table.
0 pages containing 0 free bytes are potential move destinations.
CPU 0.00s/0.03u sec elapsed 0.03 sec.
INFO:  index "tp93t_pkey" now contains 71984 row versions in 868 pages
DETAIL:  0 index pages have been deleted, 0 are currently reusable.
CPU 0.00s/0.00u sec elapsed 0.00 sec.
INFO:  vacuuming "pg_toast.pg_toast_24274"
INFO:  "pg_toast_24274": found 0 removable, 0 nonremovable row versions in 0 pages
DETAIL:  0 dead row versions cannot be removed yet.
Nonremovable row versions range from 0 to 0 bytes long.
There were 0 unused item pointers.
Total free space (including removable row versions) is 0 bytes.
0 pages are or will become empty, including 0 at the end of the table.
0 pages containing 0 free bytes are potential move destinations.
CPU 0.00s/0.00u sec elapsed 0.00 sec.
INFO:  index "pg_toast_24274_index" now contains 0 row versions in 1 pages
DETAIL:  0 index pages have been deleted, 0 are currently reusable.
CPU 0.00s/0.00u sec elapsed 0.00 sec.
VACUUM

carmen=# select count(*) from tp93t;
 count
-------
  1352
(1 row)


I did't see any transactions locking this table and I think that CLUSTER will recreate the table.

This is a temporary table, with one DELETE, Some INSERTs and a lot of UPDATES. And the UPDATES become slow and slow every time.
The only way to correct, is truncating the table.

Best regards,

Alexandre

Re: Vacuum Full + Cluster + Vacuum full = non removable dead rows

От
Scott Marlowe
Дата:
On Tue, Aug 17, 2010 at 1:19 PM, Alexandre de Arruda Paes
<adaldeia@gmail.com> wrote:
> Hi,
>
> PG 8.4.4
> I did't see any transactions locking this table and I think that CLUSTER
> will recreate the table.

Prepared transactions?

> This is a temporary table, with one DELETE, Some INSERTs and a lot of
> UPDATES. And the UPDATES become slow and slow every time.
> The only way to correct, is truncating the table.

And you're sure there aren't any "idle in transaction" connections/

Fwd: Vacuum Full + Cluster + Vacuum full = non removable dead rows

От
Alexandre de Arruda Paes
Дата:
I'm forwarding again this email to list, because Me and Scoot unfortunately was talking alone. (thanks Scott)

>So what do:
>select * from pg_stat_activity where current_query ilike '%transaction%';
>and
>select * from pg_stat_activity where now()-current_query > '1 minute'::interval;
>say?
>You should really avoid vacuum full, and stick to vacuum (plain).  At
>least until you can get the tuples to be freed up.  Each time you run
>it you bloat your indexes.

To clarify:

This is a production server with lots of connection and the commands above returns a lot of rows, but nothing related with this table (see bellow).
I know the problem with VACUUM FULL and bloated Indexes, but I don't understand why the table that is not in use by nobody, cant be vacuumed or clustered to avoid dead tuples.
Single VACUUM cant recover this dead tuples too.
 
I see an opened transaction (this is a tomcat servlet webpage), but killing this transaction does not help the VACUUM:

<webpa 192.168.1.1 2010-08-17 18:36:40.459 BRT 243345>LOG:  execute S_1: BEGIN
<webpa 192.168.1.1 2010-08-17 18:36:40.459 BRT 243346>LOG:  duration: 0.010 ms
<webpa 192.168.1.1 2010-08-17 18:36:40.459 BRT 243347>LOG:  duration: 0.362 ms
<webpa 192.168.1.1 2010-08-17 18:36:40.460 BRT 243348>LOG:  duration: 0.703 ms
<webpa 192.168.1.1 2010-08-17 18:36:40.460 BRT 243349>LOG:  execute <unnamed>: SELECT TP93usuari, TP93Objeto, TP93Ca251, TP93Nm0805, TP93Nm0804, TP93Ca501, TP93Ca2001, TP93Nm1521, TP93Nm0803, TP93Ca253, TP93Nm1522, TP93Nm0801, TP93Nm0802, TP93Chave FROM TP93T WHERE (TP93usuari = $1) AND (TP93Objeto = 'PC0658PP') AND (TP93Ca251 >= $2) ORDER BY TP93Chave
<webpa 192.168.1.1 2010-08-17 18:36:40.460 BRT 243350>DETAIL:  parameters: $1 = 'WEBCLIENTE          ', $2 = '                    '
<webpa 192.168.1.1 2010-08-17 18:36:40.469 BRT 243351>LOG:  duration: 9.302 ms

[postgres@servernew logs]$ psql carmen
psql (8.4.4)
Type "help" for help.

carmen=# select * from vlocks where relname='tp93t'; select * from pg_stat_activity where usename='webpa';

 datname | relname | virtualtransaction |      mode       | granted | usename |        substr         |          query_start          |       age       | procpid
---------+---------+--------------------+-----------------+---------+---------+-----------------------+-------------------------------+-----------------+---------
 carmen  | tp93t   | 25/4319            | AccessShareLock | t       | webpa   | <IDLE> in transaction | 2010-08-17 18:36:40.460657-03 | 00:01:09.455456 |    1917
(1 row)


 datid | datname | procpid | usesysid  | usename |     current_query     | waiting |          xact_start           |          query_start          |         backend_start         | client_addr | client_port
-------+---------+---------+-----------+---------+-----------------------+---------+-------------------------------+-------------------------------+-------------------------------+-------------+-------------
 16745 | carmen  |    1917 | 750377993 | webpa   | <IDLE> in transaction | f       | 2010-08-17 18:36:40.459531-03 | 2010-08-17 18:36:40.460657-03 | 2010-08-17 18:36:09.917687-03 | 192.168.1.1 |       39027
(1 row)

carmen=# select * from vlocks where usename='webpa';

 datname |  relname   | virtualtransaction |      mode       | granted | usename |        substr         |          query_start          |       age       | procpid
---------+------------+--------------------+-----------------+---------+---------+-----------------------+-------------------------------+-----------------+---------
 carmen  | tp93t_pkey | 25/4319            | AccessShareLock | t       | webpa   | <IDLE> in transaction | 2010-08-17 18:36:40.460657-03 | 00:01:16.618563 |    1917
 carmen  | tp93t      | 25/4319            | AccessShareLock | t       | webpa   | <IDLE> in transaction | 2010-08-17 18:36:40.460657-03 | 00:01:16.618563 |    1917
 carmen  |            | 25/4319            | ExclusiveLock   | t       | webpa   | <IDLE> in transaction | 2010-08-17 18:36:40.460657-03 | 00:01:16.618563 |    1917
(3 rows)

-----------------------------------------------------------------------------------------------

OK, I will kill the backend and run vacuum:

carmen=# select pg_terminate_backend(1917);
 pg_terminate_backend
----------------------
 t
(1 row)

carmen=# select * from vlocks where relname='tp93t'; select * from pg_stat_activity where usename='webpa';

 datname | relname | virtualtransaction | mode | granted | usename | substr | query_start | age | procpid
---------+---------+--------------------+------+---------+---------+--------+-------------+-----+---------
(0 rows)

 datid | datname | procpid | usesysid  | usename |     current_query     | waiting |          xact_start           |          query_start          |         backend_start         | client_addr | client_port
-------+---------+---------+--
---------+---------+-----------------------+---------+-------------------------------+-------------------------------+-------------------------------+-------------+-------------
(0 rows)


carmen=# VACUUM verbose tp93t;
INFO:  vacuuming "public.tp93t"
INFO:  index "tp93t_pkey" now contains 5592 row versions in 103 pages
DETAIL:  0 index row versions were removed.
0 index pages have been deleted, 0 are currently reusable.
CPU 0.00s/0.00u sec elapsed 0.00 sec.
INFO:  "tp93t": found 0 removable, 19336 nonremovable row versions in 4887 out of 4887 pages
DETAIL:  19126 dead row versions cannot be removed yet.


carmen=# VACUUM FULL verbose tp93t;
INFO:  vacuuming "public.tp93t"
INFO:  "tp93t": found 0 removable, 19336 nonremovable row versions in 4887 pages
DETAIL:  19126 dead row versions cannot be removed yet.
Nonremovable row versions range from 1853 to 2029 bytes long.
There were 210 unused item pointers.
(...)







2010/8/17 Scott Marlowe <scott.marlowe@gmail.com>
On Tue, Aug 17, 2010 at 2:28 PM, Alexandre de Arruda Paes

<adaldeia@gmail.com> wrote:

So what do:
select * from pg_stat_activity where current_query ilike '%transaction%';
and
select * from pg_stat_activity where now()-current_query > '1 minute'::interval;
say?

> And its the dead rows is growing:
>
> carmen=# VACUUM FULL verbose tp93t;

You should really avoid vacuum full, and stick to vacuum (plain).  At
least until you can get the tuples to be freed up.  Each time you run
it you bloat your indexes.

> INFO:  vacuuming "public.tp93t"
> INFO:  "tp93t": found 1309 removable, 313890 nonremovable row versions in
> 78800 pages
> DETAIL:  312581 dead row versions cannot be removed yet.
> Nonremovable row versions range from 1845 to 2032 bytes long.
> There were 3014 unused item pointers.


--
To understand recursion, one must first understand recursion.


Re: Fwd: Vacuum Full + Cluster + Vacuum full = non removable dead rows

От
Tom Lane
Дата:
Alexandre de Arruda Paes <adaldeia@gmail.com> writes:
> I know the problem with VACUUM FULL and bloated Indexes, but I don't
> understand why the table that is not in use by nobody, cant be vacuumed or
> clustered to avoid dead tuples.

There's an open transaction somewhere that VACUUM is preserving the
tuples for.  This transaction need not ever have touched the table,
or ever intend to touch the table --- but VACUUM cannot know that,
so it saves any tuples that the transaction might be entitled to see
if it looked.

> carmen=# select * from vlocks where relname='tp93t'; select * from
> pg_stat_activity where usename='webpa';

You keep on showing us only subsets of pg_stat_activity :-(

Also, if you don't see anything in pg_stat_activity, try pg_prepared_xacts.

            regards, tom lane

Re: Fwd: Vacuum Full + Cluster + Vacuum full = non removable dead rows

От
Alexandre de Arruda Paes
Дата:
Hi Tom,

Below, the pg_prepared_xacts result.
The only way to restore the table is with TRUNCATE.
Vacuum, Vacuum full,  cluster not help and subsequent updates will become slow and slow.


carmen=# select * from vlocks where relname='tp93t'; select * from pg_stat_activity where usename='webpa'; select * from pg_prepared_xacts;
 datname | relname | virtualtransaction | mode | granted | usename | substr | query_start | age | procpid
---------+---------+--------------------+------+---------+---------+--------+-------------+-----+---------
(0 rows)

 datid | datname | procpid | usesysid  | usename | current_query | waiting | xact_start |          query_start          |         backend_start         | client_addr | client_port
-------+---------+---------+-----------+---------+---------------+---------+------------+-------------------------------+-------------------------------+-------------+-------------
 16745 | carmen  |   19345 | 750377993 | webpa   | <IDLE>        | f       |            | 2010-08-19 09:40:44.295753-03 | 2010-08-19 09:38:45.637543-03 | 192.168.1.1 |       59867
(1 row)

 transaction | gid | prepared | owner | database
-------------+-----+----------+-------+----------
(0 rows)

carmen=# VACUUM full verbose tp93t;
INFO:  vacuuming "public.tp93t"
INFO:  "tp93t": found 0 removable, 38588 nonremovable row versions in 9700 pages
DETAIL:  38378 dead row versions cannot be removed yet.
Nonremovable row versions range from 1853 to 2029 bytes long.
There were 317 unused item pointers.
Total free space (including removable row versions) is 1178860 bytes.
0 pages are or will become empty, including 0 at the end of the table.
190 pages containing 442568 free bytes are potential move destinations.
CPU 0.00s/0.02u sec elapsed 0.02 sec.
INFO:  index "tp93t_pkey" now contains 11597 row versions in 195 pages
DETAIL:  0 index row versions were removed.
0 index pages have been deleted, 0 are currently reusable.
CPU 0.00s/0.00u sec elapsed 0.00 sec.
INFO:  "tp93t": moved 0 row versions, truncated 9700 to 9700 pages
DETAIL:  CPU 0.00s/0.00u sec elapsed 0.00 sec.
INFO:  vacuuming "pg_toast.pg_toast_24274"
INFO:  "pg_toast_24274": found 0 removable, 0 nonremovable row versions in 0 pages
DETAIL:  0 dead row versions cannot be removed yet.
Nonremovable row versions range from 0 to 0 bytes long.
There were 0 unused item pointers.
Total free space (including removable row versions) is 0 bytes.
0 pages are or will become empty, including 0 at the end of the table.
0 pages containing 0 free bytes are potential move destinations.
CPU 0.00s/0.00u sec elapsed 0.00 sec.
INFO:  index "pg_toast_24274_index" now contains 0 row versions in 1 pages
DETAIL:  0 index pages have been deleted, 0 are currently reusable.
CPU 0.00s/0.00u sec elapsed 0.00 sec.
VACUUM


2010/8/18 Tom Lane <tgl@sss.pgh.pa.us>
Alexandre de Arruda Paes <adaldeia@gmail.com> writes:
> I know the problem with VACUUM FULL and bloated Indexes, but I don't
> understand why the table that is not in use by nobody, cant be vacuumed or
> clustered to avoid dead tuples.

There's an open transaction somewhere that VACUUM is preserving the
tuples for.  This transaction need not ever have touched the table,
or ever intend to touch the table --- but VACUUM cannot know that,
so it saves any tuples that the transaction might be entitled to see
if it looked.

> carmen=# select * from vlocks where relname='tp93t'; select * from
> pg_stat_activity where usename='webpa';

You keep on showing us only subsets of pg_stat_activity :-(

Also, if you don't see anything in pg_stat_activity, try pg_prepared_xacts.

                       regards, tom lane

Re: Fwd: Vacuum Full + Cluster + Vacuum full = non removable dead rows

От
"Kevin Grittner"
Дата:
Alexandre de Arruda Paes <adaldeia@gmail.com> wrote:
> 2010/8/18 Tom Lane <tgl@sss.pgh.pa.us>

>> There's an open transaction somewhere that VACUUM is preserving
>> the tuples for.  This transaction need not ever have touched the
>> table, or ever intend to touch the table --- but VACUUM cannot
>> know that, so it saves any tuples that the transaction might be
>> entitled to see if it looked.
>>
>> > carmen=# select * from vlocks where relname='tp93t'; select *
>> > from pg_stat_activity where usename='webpa';
>>
>> You keep on showing us only subsets of pg_stat_activity :-(

> select * from pg_stat_activity where usename='webpa';

You keep on showing us only subsets of pg_stat_activity :-(

*ANY* open transaction, including "idle in transaction" including
transactions by other users in other databases will prevent vacuum
from cleaning up rows, for the reasons Tom already gave you.

What do you get from?:

select * from pg_stat_activity where current_query <> '<IDLE>'
  order by xact_start limit 10;

-Kevin

Re: Fwd: Vacuum Full + Cluster + Vacuum full = non removable dead rows

От
Tom Lane
Дата:
Alexandre de Arruda Paes <adaldeia@gmail.com> writes:
> Below, the pg_prepared_xacts result.

OK, so you don't have any prepared transactions, but you're still not
showing us the full content of pg_stat_activity.

Just out of curiosity, how many rows does "select count(*) from tp93t"
think there are?

            regards, tom lane

Re: Fwd: Vacuum Full + Cluster + Vacuum full = non removable dead rows

От
Dimitri
Дата:
So, does it mean that VACUUM will never clean dead rows if you have a
non-stop transactional activity in your PG database???... (24/7 OLTP
for ex.)

Rgds,
-Dimitri


On 8/19/10, Kevin Grittner <Kevin.Grittner@wicourts.gov> wrote:
> Alexandre de Arruda Paes <adaldeia@gmail.com> wrote:
>> 2010/8/18 Tom Lane <tgl@sss.pgh.pa.us>
>
>>> There's an open transaction somewhere that VACUUM is preserving
>>> the tuples for.  This transaction need not ever have touched the
>>> table, or ever intend to touch the table --- but VACUUM cannot
>>> know that, so it saves any tuples that the transaction might be
>>> entitled to see if it looked.
>>>
>>> > carmen=# select * from vlocks where relname='tp93t'; select *
>>> > from pg_stat_activity where usename='webpa';
>>>
>>> You keep on showing us only subsets of pg_stat_activity :-(
>
>> select * from pg_stat_activity where usename='webpa';
>
> You keep on showing us only subsets of pg_stat_activity :-(
>
> *ANY* open transaction, including "idle in transaction" including
> transactions by other users in other databases will prevent vacuum
> from cleaning up rows, for the reasons Tom already gave you.
>
> What do you get from?:
>
> select * from pg_stat_activity where current_query <> '<IDLE>'
>   order by xact_start limit 10;
>
> -Kevin
>
> --
> Sent via pgsql-performance mailing list (pgsql-performance@postgresql.org)
> To make changes to your subscription:
> http://www.postgresql.org/mailpref/pgsql-performance
>

Re: Fwd: Vacuum Full + Cluster + Vacuum full = non removable dead rows

От
Scott Marlowe
Дата:
No, it means it can't clean rows that are younger than the oldest
transaction currently in progress.  if you started a transaction 5
hours ago, then all the dead tuples created in the last 5 hours are
not recoverable.  Dead tuples created before that transaction are
recoverable.  If you run transactions for days or weeks, then you're
gonna have issues.

On Sat, Aug 21, 2010 at 2:25 AM, Dimitri <dimitrik.fr@gmail.com> wrote:
> So, does it mean that VACUUM will never clean dead rows if you have a
> non-stop transactional activity in your PG database???... (24/7 OLTP
> for ex.)
>
> Rgds,
> -Dimitri
>
>
> On 8/19/10, Kevin Grittner <Kevin.Grittner@wicourts.gov> wrote:
>> Alexandre de Arruda Paes <adaldeia@gmail.com> wrote:
>>> 2010/8/18 Tom Lane <tgl@sss.pgh.pa.us>
>>
>>>> There's an open transaction somewhere that VACUUM is preserving
>>>> the tuples for.  This transaction need not ever have touched the
>>>> table, or ever intend to touch the table --- but VACUUM cannot
>>>> know that, so it saves any tuples that the transaction might be
>>>> entitled to see if it looked.
>>>>
>>>> > carmen=# select * from vlocks where relname='tp93t'; select *
>>>> > from pg_stat_activity where usename='webpa';
>>>>
>>>> You keep on showing us only subsets of pg_stat_activity :-(
>>
>>> select * from pg_stat_activity where usename='webpa';
>>
>> You keep on showing us only subsets of pg_stat_activity :-(
>>
>> *ANY* open transaction, including "idle in transaction" including
>> transactions by other users in other databases will prevent vacuum
>> from cleaning up rows, for the reasons Tom already gave you.
>>
>> What do you get from?:
>>
>> select * from pg_stat_activity where current_query <> '<IDLE>'
>>   order by xact_start limit 10;
>>
>> -Kevin
>>
>> --
>> Sent via pgsql-performance mailing list (pgsql-performance@postgresql.org)
>> To make changes to your subscription:
>> http://www.postgresql.org/mailpref/pgsql-performance
>>
>
> --
> Sent via pgsql-performance mailing list (pgsql-performance@postgresql.org)
> To make changes to your subscription:
> http://www.postgresql.org/mailpref/pgsql-performance
>



--
To understand recursion, one must first understand recursion.

Re: Fwd: Vacuum Full + Cluster + Vacuum full = non removable dead rows

От
Dimitri
Дата:
Great! - it's what I expected until now :-)
but discussion in this thread put my mind in trouble :-))

So, the advice for Alexandre here is just to check the age of the
oldest running transaction and the last time when the table in
question was modified.. - if modification time is older than the
oldest transaction = we have a problem in PG.. Otherwise it works as
expected to match MVCC.

Rgds,
-Dimitri


On 8/21/10, Scott Marlowe <scott.marlowe@gmail.com> wrote:
> No, it means it can't clean rows that are younger than the oldest
> transaction currently in progress.  if you started a transaction 5
> hours ago, then all the dead tuples created in the last 5 hours are
> not recoverable.  Dead tuples created before that transaction are
> recoverable.  If you run transactions for days or weeks, then you're
> gonna have issues.
>
> On Sat, Aug 21, 2010 at 2:25 AM, Dimitri <dimitrik.fr@gmail.com> wrote:
>> So, does it mean that VACUUM will never clean dead rows if you have a
>> non-stop transactional activity in your PG database???... (24/7 OLTP
>> for ex.)
>>
>> Rgds,
>> -Dimitri
>>
>>
>> On 8/19/10, Kevin Grittner <Kevin.Grittner@wicourts.gov> wrote:
>>> Alexandre de Arruda Paes <adaldeia@gmail.com> wrote:
>>>> 2010/8/18 Tom Lane <tgl@sss.pgh.pa.us>
>>>
>>>>> There's an open transaction somewhere that VACUUM is preserving
>>>>> the tuples for.  This transaction need not ever have touched the
>>>>> table, or ever intend to touch the table --- but VACUUM cannot
>>>>> know that, so it saves any tuples that the transaction might be
>>>>> entitled to see if it looked.
>>>>>
>>>>> > carmen=# select * from vlocks where relname='tp93t'; select *
>>>>> > from pg_stat_activity where usename='webpa';
>>>>>
>>>>> You keep on showing us only subsets of pg_stat_activity :-(
>>>
>>>> select * from pg_stat_activity where usename='webpa';
>>>
>>> You keep on showing us only subsets of pg_stat_activity :-(
>>>
>>> *ANY* open transaction, including "idle in transaction" including
>>> transactions by other users in other databases will prevent vacuum
>>> from cleaning up rows, for the reasons Tom already gave you.
>>>
>>> What do you get from?:
>>>
>>> select * from pg_stat_activity where current_query <> '<IDLE>'
>>>   order by xact_start limit 10;
>>>
>>> -Kevin
>>>
>>> --
>>> Sent via pgsql-performance mailing list
>>> (pgsql-performance@postgresql.org)
>>> To make changes to your subscription:
>>> http://www.postgresql.org/mailpref/pgsql-performance
>>>
>>
>> --
>> Sent via pgsql-performance mailing list (pgsql-performance@postgresql.org)
>> To make changes to your subscription:
>> http://www.postgresql.org/mailpref/pgsql-performance
>>
>
>
>
> --
> To understand recursion, one must first understand recursion.
>

Re: Fwd: Vacuum Full + Cluster + Vacuum full = non removable dead rows

От
Alexandre de Arruda Paes
Дата:
2010/8/21 Dimitri <dimitrik.fr@gmail.com>
Great! - it's what I expected until now :-)
but discussion in this thread put my mind in trouble :-))

So, the advice for Alexandre here is just to check the age of the
oldest running transaction and the last time when the table in
question was modified.. - if modification time is older than the
oldest transaction = we have a problem in PG.. Otherwise it works as
expected to match MVCC.

Rgds,
-Dimitri


Unfortunately, the customer can't wait for the solution and the programmer eliminated the
use of this table by using a in-memory array.

I understood that all transactions, touching this table or not, can affect the ability of the vacuum to recover the dead tuples.
In my scenario, it's too bad because I have long transactions and I really not know when I will recover this tuples.
And, like I sad, the table will become more slow every time.

Only for discussion: the CLUSTER command, in my little knowledge, is a intrusive command that's cannot recover the dead tuples too.

Only TRUNCATE can do this job, but obviously is not applicable all the time.

Best regards,

Alexandre



On 8/21/10, Scott Marlowe <scott.marlowe@gmail.com> wrote:
> No, it means it can't clean rows that are younger than the oldest
> transaction currently in progress.  if you started a transaction 5
> hours ago, then all the dead tuples created in the last 5 hours are
> not recoverable.  Dead tuples created before that transaction are
> recoverable.  If you run transactions for days or weeks, then you're
> gonna have issues.
>
> On Sat, Aug 21, 2010 at 2:25 AM, Dimitri <dimitrik.fr@gmail.com> wrote:
>> So, does it mean that VACUUM will never clean dead rows if you have a
>> non-stop transactional activity in your PG database???... (24/7 OLTP
>> for ex.)
>>
>> Rgds,
>> -Dimitri
>>
>>
>> On 8/19/10, Kevin Grittner <Kevin.Grittner@wicourts.gov> wrote:
>>> Alexandre de Arruda Paes <adaldeia@gmail.com> wrote:
>>>> 2010/8/18 Tom Lane <tgl@sss.pgh.pa.us>
>>>
>>>>> There's an open transaction somewhere that VACUUM is preserving
>>>>> the tuples for.  This transaction need not ever have touched the
>>>>> table, or ever intend to touch the table --- but VACUUM cannot
>>>>> know that, so it saves any tuples that the transaction might be
>>>>> entitled to see if it looked.
>>>>>
>>>>> > carmen=# select * from vlocks where relname='tp93t'; select *
>>>>> > from pg_stat_activity where usename='webpa';
>>>>>
>>>>> You keep on showing us only subsets of pg_stat_activity :-(
>>>
>>>> select * from pg_stat_activity where usename='webpa';
>>>
>>> You keep on showing us only subsets of pg_stat_activity :-(
>>>
>>> *ANY* open transaction, including "idle in transaction" including
>>> transactions by other users in other databases will prevent vacuum
>>> from cleaning up rows, for the reasons Tom already gave you.
>>>
>>> What do you get from?:
>>>
>>> select * from pg_stat_activity where current_query <> '<IDLE>'
>>>   order by xact_start limit 10;
>>>
>>> -Kevin
>>>
>>> --
>>> Sent via pgsql-performance mailing list
>>> (pgsql-performance@postgresql.org)
>>> To make changes to your subscription:
>>> http://www.postgresql.org/mailpref/pgsql-performance
>>>
>>
>> --
>> Sent via pgsql-performance mailing list (pgsql-performance@postgresql.org)
>> To make changes to your subscription:
>> http://www.postgresql.org/mailpref/pgsql-performance
>>
>
>
>
> --
> To understand recursion, one must first understand recursion.
>

Re: Fwd: Vacuum Full + Cluster + Vacuum full = non removable dead rows

От
Robert Haas
Дата:
On Sat, Aug 21, 2010 at 9:49 AM, Alexandre de Arruda Paes
<adaldeia@gmail.com> wrote:
> Only for discussion: the CLUSTER command, in my little knowledge, is a
> intrusive command that's cannot recover the dead tuples too.
>
> Only TRUNCATE can do this job, but obviously is not applicable all the time.

Either VACUUM or CLUSTER will recover *dead* tuples.  What you can't
recover are tuples that are still visible to some running transaction.

--
Robert Haas
EnterpriseDB: http://www.enterprisedb.com
The Enterprise Postgres Company

Re: Fwd: Vacuum Full + Cluster + Vacuum full = non removable dead rows

От
Dimitri
Дата:
The problem here is that we're trying to keep an image of a whole
world for any transaction which is in most cases will need to get a
look on few streets around.. ;-)
I understand well that it's respecting the standard and so on, but the
background problem that you may see your table bloated just because
there is a long running transaction appeared in another database, and
if it's maintained/used/etc by another team - the problem very quickly
may become human rather technical :-))

So, why simply don't add a FORCE option to VACUUM?.. - In this case if
one executes "VACUUM FORCE TABLE" will be just aware about what he's
doing and be sure no one of the active transactions will be ever
access this table.

What do you think?.. ;-)

Rgds,
-Dimitri


On 8/22/10, Robert Haas <robertmhaas@gmail.com> wrote:
> On Sat, Aug 21, 2010 at 9:49 AM, Alexandre de Arruda Paes
> <adaldeia@gmail.com> wrote:
>> Only for discussion: the CLUSTER command, in my little knowledge, is a
>> intrusive command that's cannot recover the dead tuples too.
>>
>> Only TRUNCATE can do this job, but obviously is not applicable all the
>> time.
>
> Either VACUUM or CLUSTER will recover *dead* tuples.  What you can't
> recover are tuples that are still visible to some running transaction.
>
> --
> Robert Haas
> EnterpriseDB: http://www.enterprisedb.com
> The Enterprise Postgres Company
>
> --
> Sent via pgsql-performance mailing list (pgsql-performance@postgresql.org)
> To make changes to your subscription:
> http://www.postgresql.org/mailpref/pgsql-performance
>

Re: Fwd: Vacuum Full + Cluster + Vacuum full = non removable dead rows

От
Greg Smith
Дата:
Dimitri wrote:
> I understand well that it's respecting the standard and so on, but the
> background problem that you may see your table bloated just because
> there is a long running transaction appeared in another database, and
> if it's maintained/used/etc by another team - the problem very quickly
> may become human rather technical :-))
>

The way VACUUM and autovacuum work by default, it's OK to expect just
over 20% of the database rows to be bloat from dead rows.  On some
systems that much overhead is still too much, but on others the system
continues to operate just fine with that quantity of bloat.  It's not
unreasonable, and is recoverable once the long running transaction finishes.

If your application has a component to it that allows a transaction to
run for so long that more than 20% of a table can be dead before it
completes, you have a technical problem.  The technical solution may not
be simple or obvious, but you need to find one--not say "the person
shouldn't have done that".  Users should never have gotten an API
exposed to them where it's possible for them to screw things up that
badly.  The usual first round of refactoring here is to figuring out how
to break transactions into smaller chunks usefully, which tends to
improve other performance issues too, and then they don't run for so
long either.

> So, why simply don't add a FORCE option to VACUUM?.. - In this case if
> one executes "VACUUM FORCE TABLE" will be just aware about what he's
> doing and be sure no one of the active transactions will be ever
> access this table.
>

See above.  If you've gotten into this situation, you do not need a
better hammer to smack the part of the server that is stuck.  One would
be almost impossible to build, and have all sorts of side effects it's
complicated to explain.  It's far simpler to just avoid to known and
common design patterns that lead to this class of problem in the first
place.  This is a database application coding problem, not really a
database internals one.

--
Greg Smith  2ndQuadrant US  Baltimore, MD
PostgreSQL Training, Services and Support
greg@2ndQuadrant.com   www.2ndQuadrant.us


Re: Fwd: Vacuum Full + Cluster + Vacuum full = non removable dead rows

От
Greg Smith
Дата:
Alexandre de Arruda Paes wrote:
> Unfortunately, the customer can't wait for the solution and the
> programmer eliminated the
> use of this table by using a in-memory array.

Well that will be fun.  Now they've traded their old problem for a new
one--cache inconsistency between the data in memory and what sitting in
the database.  The fun apart about that is that the cache mismatch bugs
you'll run into are even more subtle, frustrating, and difficult to
replicate on demand than the VACUUM ones.

> Only for discussion: the CLUSTER command, in my little knowledge, is a
> intrusive command that's cannot recover the dead tuples too.
> Only TRUNCATE can do this job, but obviously is not applicable all the
> time.

Yes, CLUSTER takes a full lock on the table and rewrites a new one with
all the inactive data removed.  The table is unavailable to anyone else
while that's happening.

Some designs separate their data into partitions in a way that it's
possible to TRUNCATE/DROP the ones that are no longer relevant (and are
possibly filled with lots of dead rows) in order to clean them up
without using VACUUM.  This won't necessarily help with long-running
transactions though.  If those are still referring to do data in those
old partitions, removing them will be blocked for the same reason VACUUM
can't clean up inside of them--they data is still being used by an
active transaction.

--
Greg Smith  2ndQuadrant US  Baltimore, MD
PostgreSQL Training, Services and Support
greg@2ndQuadrant.com   www.2ndQuadrant.us