Hi Pavlos

This is my understanding of why you were not able to run the query fast
enough after the vacuum analyze. This is possibly what would have happened:


   1. The relation has 5 million expired URLs and 5 thousand non-expired
   URLs
   2. Assuming that the table only has 5 million and 5 thousand tuples,
   once you delete the expired ones, there will be an autovacuum triggered.
   “If the number of tuples obsoleted since the last VACUUM exceeds the
   “vacuum threshold”, the table is vacuumed“ -
   https://www.postgresql.org/docs/current/routine-vacuuming.html#AUTOVACUUM
   ; As the Analyze threshold will also be exceeded, that would also have been
   run by autovacuum alongside.
   3. The status of this autovacuum (if it is running or blocked), could
   have been checked in the pg_stat_activity.
   4. Note, autovacuum does not trigger to clean up the dead tuples if it
   is disabled for the relation (or in the postgresql.conf file). However, if
   you would have taken transaction IDs to the threshold of
   autovacuum_freeze_max_age, autovacuum would trigger to FREEZE transaction
   IDs even if disabled.
   5. As you stated its a t3.micro instance, they have limited resources,
   so it could be that the autovacuum was slow running (again, this can be
   checked in pg_stat_activity).
   6. Given that you manually ran a VACUUM ANALYZE and it did not make the
   query faster, could be due to internal fragmentation. You are right, Vacuum
   does not release the space back to the operating system in most cases. This
   statement is the documentation that can clarify this for you :
   “The standard form of VACUUM removes dead row versions in tables and
   indexes and marks the space available for future reuse. However, it will
   not return the space to the operating system, except in the special case
   where one or more pages at the end of a table become entirely free and an
   exclusive table lock can be easily obtained. In contrast, VACUUM FULL
   actively compacts tables by writing a complete new version of the table
   file with no dead space. This minimizes the size of the table, but can take
   a long time. It also requires extra disk space for the new copy of the
   table, until the operation completes.”
   
https://www.postgresql.org/docs/current/routine-vacuuming.html#VACUUM-FOR-SPACE-RECOVERY
   7. This basically means that once you ran a VACUUM FULL, it might have
   actually shrunk the table quite significantly, which made the query to be
   much faster.
   8. You could have compared the size of the table before and after the
   VACUUM FULL to understand this better.


Just a few suggestion for doing bulk removal of data :

   - It would be worth looking into pg_repack for such bulk deletes rather
   than vacuum full as the former does not take an exclusive lock for the
   entire duration of the operation - https://reorg.github.io/pg_repack/ .
   However, you will still need double the space of the table, as it also
   recreates the table.
   - Another way of doing bulk removal of data would be to do a CTAS (
   https://www.postgresql.org/docs/14/sql-createtableas.html) to a new
   table with the live data (in your case the 5 thousand tuples), and then
   dropping the old table (which means no dead tuples). You might need a
   trigger in between to make sure all the live data during use is transferred
   to the new table.
   - You might want to look into partitioning and drop the partitions once
   the URLs in that particular partition are no longer needed (Like URLs older
   than 6 months).



Kind Regards
Divya Sharma


On Tue, Jan 30, 2024 at 8:38 PM David Rowley <dgrowle...@gmail.com> wrote:

> On Wed, 31 Jan 2024 at 09:09, Philip Semanchuk
> <phi...@americanefficient.com> wrote:
> > So in your case those 5m rows that you deleted were probably still
> clogging up your table until you ran VACUUM FULL.
>
> It seems more likely to me that the VACUUM removed the rows and just
> left empty pages in the table.  Since there's no index on expires_at,
> the only way to answer that query is to Seq Scan and Seq Scan will
> need to process those empty pages.  While that processing is very fast
> if the page's item pointers array is empty, it could still be slow if
> the page needs to be read from disk. Laurenz's request for the explain
> (analyze, buffers) output with track_io_timing on will help confirm
> this.
>
> If it is just reading empty pages that's causing this issue then
> adding that missing index would improve the situation after running
> just plain VACUUM each time there's a bulk delete.
>
> David
>
>
>

Reply via email to