Thread: [ADMIN] Vacuum not removing dead tuples
Is there a reason vacuum will not remove dead tuples other than the usual suspects? There are no two phase transactions and even after a restoring the database from binary backup with nothing connect to the restored instance; vacuum still does not remove the dead tuples.
psql: FATAL: the database system is starting up
[postgres@pgdb02 ~]$ psql
psql (9.6.5)
Type "help" for help.
pgdb02=# vacuum verbose prod.bb_rate;
INFO: vacuuming "prod.bb_rate"
INFO: index "bb_rate_pkey" now contains 210082099 row versions in 495747 pages
DETAIL: 0 index row versions were removed.
1 index pages have been deleted, 0 are currently reusable.
CPU 7.55s/1.35u sec elapsed 12.99 sec.
INFO: index "bb_rate_idx1" now contains 210082099 row versions in 678445 pages
DETAIL: 0 index row versions were removed.
474 index pages have been deleted, 0 are currently reusable.
CPU 10.46s/2.07u sec elapsed 24.67 sec.
INFO: "bb_rate": found 0 removable, 190511368 nonremovable row versions in 1070330 out of 2038195 pages
DETAIL: 171750178 dead row versions cannot be removed yet.
There were 28676154 unused item pointers.
Skipped 0 pages due to buffer pins.
0 pages are entirely empty.
CPU 71.52s/45.55u sec elapsed 228.24 sec.
INFO: vacuuming "pg_toast.pg_toast_419371"
INFO: index "pg_toast_419371_index" now contains 0 row versions in 1 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: "pg_toast_419371": found 0 removable, 0 nonremovable row versions in 0 out of 0 pages
DETAIL: 0 dead row versions cannot be removed yet.
There were 0 unused item pointers.
Skipped 0 pages due to buffer pins.
0 pages are entirely empty.
CPU 0.00s/0.00u sec elapsed 0.00 sec.
Rui DeSousa wrote: > Is there a reason vacuum will not remove dead tuples other than the usual suspects? > There are no two phase transactions and even after a restoring the database > from binary backup with nothing connect to the restored instance; > vacuum still does not remove the dead tuples. There are three possibilities: 1) Active transactions: SELECT backend_xmin, xact_start, datname, pid, query FROM pg_stat_activity WHERE state <> 'idle' ORDER BY xact_start; 2) Prepared transactions: SELECT xid, prepared FROM pg_prepared_xacts; 3) Lagging replication slots: SELECT xmin, slot_name, active, active_pid FROM pg_replication_slots; The "xid" columns will tell you which tuples VACUUM can remove: Any tuple with "xmax" less than this are fair game. Yours, Laurenz Albe -- Sent via pgsql-admin mailing list (pgsql-admin@postgresql.org) To make changes to your subscription: http://www.postgresql.org/mailpref/pgsql-admin
Thanks Laurenz, A replication slot was my issue. Much appreciated for the insight. Thanks, Rui > On Nov 15, 2017, at 5:06 AM, Laurenz Albe <laurenz.albe@cybertec.at> wrote: > > Rui DeSousa wrote: >> Is there a reason vacuum will not remove dead tuples other than the usual suspects? >> There are no two phase transactions and even after a restoring the database >> from binary backup with nothing connect to the restored instance; >> vacuum still does not remove the dead tuples. > > There are three possibilities: > > 1) Active transactions: > > SELECT backend_xmin, xact_start, datname, pid, query > FROM pg_stat_activity > WHERE state <> 'idle' > ORDER BY xact_start; > > 2) Prepared transactions: > > SELECT xid, prepared > FROM pg_prepared_xacts; > > 3) Lagging replication slots: > > SELECT xmin, slot_name, active, active_pid > FROM pg_replication_slots; > > The "xid" columns will tell you which tuples VACUUM can > remove: Any tuple with "xmax" less than this are fair game. > > Yours, > Laurenz Albe -- Sent via pgsql-admin mailing list (pgsql-admin@postgresql.org) To make changes to your subscription: http://www.postgresql.org/mailpref/pgsql-admin