Trigger more frequent autovacuums of heavy insert tables
Hi,
Because of the way autovacuum_vacuum_[insert]_scale_factor works,
autovacuums trigger less frequently as the relation gets larger.
See this math in relation_needs_vacanalyze:
vacinsthresh = (float4) vac_ins_base_thresh + vac_ins_scale_factor * reltuples;
For an insert-only table, nearly all the unvacuumed pages will be
eligible to be set all-visible and many will be eligible to be set
all-frozen.
Because normal vacuums can skip all-visible pages, proactively setting
these pages all-visible by vacuuming them sooner often reduces IO
overhead, as they are more likely to still be in shared buffers the
sooner they are vacuumed after last being touched.
Vacuuming these pages more proactively and setting them frozen also
helps amortize the work of aggressive vacuums -- which often
negatively impact the performance of the system.
By considering only the unfrozen portion of the table when calculating
the vacuum insert threshold, we can trigger vacuums more proactively
on insert-heavy tables. This changes the definition of
insert_scale_factor to a percentage of "active" table size. The
attached patch does this.
I've estimated the unfrozen percentage of the table by adding a new
field to pg_class, relallfrozen, which is updated in the same places
as relallvisible.
As an example of this patch in action, I designed a benchmark in which
a table is bulk-loaded with 1 GB of data with COPY FREEZE. Then I run
a custom pgbench with four clients inserting 10 tuples per transaction
into the table for 1_000_000 transactions each.
Note that I configured Postgres to try and observe the effects of this
patch on a compressed timeline. At the bottom of the mail, I've
included details on all of the GUCs I set and why.
Over the course of the same number of transactions, master triggered 8
autovacuums of the table and the patch triggered 16.
With the patch, despite doing twice as many vacuums, autovacuum
workers did 10% fewer reads and 93% fewer writes.
At the end of the benchmark, the patched version of Postgres had
emitted twice as many FPIs as master.
More frequent vacuums means each vacuum scans fewer pages, but, more
interestingly, the first vacuum after a checkpoint is much more
efficient. With the patch, the first vacuum after a checkpoint emits
half as many FPIs. You can see that only 18 pages were newly dirtied.
So, with the patch, the pages being vacuumed are usually still in
shared buffers and still dirty.
Master
------
2024-10-22 13:53:14.293 EDT [3594] LOG: checkpoint starting: time
2024-10-22 13:53:27.849 EDT [3964] LOG: automatic vacuum of table "history"
pages: 0 removed, 753901 remain, 151589 scanned (20.11% of total)
I/O timings: read: 77.962 ms, write: 92.879 ms
avg read rate: 95.840 MB/s, avg write rate: 96.852 MB/s
buffer usage: 268318 hits, 35133 reads, 35504 dirtied
WAL usage: 218320 records, 98672 full page images, 71314906 bytes
Patch
-----
2024-10-22 13:48:43.951 EDT [1471] LOG: checkpoint starting: time
2024-10-22 13:48:59.741 EDT [1802] LOG: automatic vacuum of table "history"
pages: 0 removed, 774375 remain, 121367 scanned (15.67% of total)
I/O timings: read: 2.974 ms, write: 4.434 ms
avg read rate: 1.363 MB/s, avg write rate: 0.126 MB/s
buffer usage: 242817 hits, 195 reads, 18 dirtied
WAL usage: 121389 records, 49216 full page images, 34408291 bytes
While it is true that timing will change significantly from run to
run, I observed over many runs that the more frequent vacuums of the
table led to less overall overhead due to vacuuming pages before they
are evicted from shared buffers.
Below is a detailed description of the benchmark and Postgres configuration:
Benchmark
=========
Set these GUCs:
-- initial table data should fill shared buffers
shared_buffers=1GB
-- give us a chance to try and vacuum the table a bunch of times
autovacuum_naptime=2
-- all checkpoints should be triggered by timing
max/min_wal_size=150GB
-- let's get at least 1 checkpoint during the short benchmark
checkpoint_timeout='2min'
-- let's not be bottlenecked on WAL I/O
wal_buffers='128MB'
wal_compression='zstd'
-- let's get a lot of inserts done quickly
synchronous_commit='off'
-- let's not take too many breaks for vacuum delay
vacuum_cost_limit = 2000
-- so we can see what happened
log_checkpoints = on
log_autovacuum_min_duration=0
-- so we can get more stats
track_wal_io_timing=on
track_io_timing = on
First I created the table that you will see later in DDL and loaded it
by running pgbench in the same way as I do in the benchmark until
there was 1 GB of table data. Then I copied that out to a file
'history.data'
I included an index because the more up-to-date visibility map would
benefit index-only scans -- which you could add to the benchmark if
you want.
DDL
--
BEGIN;
DROP TABLE IF EXISTS history;
CREATE TABLE history(
id BIGINT,
client_id INT NOT NULL,
mtime TIMESTAMPTZ DEFAULT NOW(),
data TEXT);
COPY history FROM 'history.data' WITH (freeze on);
CREATE INDEX ON history(id);
COMMIT;
pgbench \
--random-seed=0 \
--no-vacuum \
-M prepared \
-c 4 \
-j 4 \
-t 1000000 \
-R 27000 \
-f- <<EOF
INSERT INTO history(id, client_id, data)
VALUES
(:client_id, :client_id, repeat('a', 90)),
(:client_id, :client_id, repeat('b', 90)),
(:client_id, :client_id, repeat('c', 90)),
(:client_id, :client_id, repeat('d', 90)),
(:client_id, :client_id, repeat('e', 90)),
(:client_id, :client_id, repeat('f', 90)),
(:client_id, :client_id, repeat('g', 90)),
(:client_id, :client_id, repeat('h', 90)),
(:client_id, :client_id, repeat('i', 90)),
(:client_id, :client_id, repeat('j', 90));
EOF
- Melanie
Attachments:
v1-0002-Trigger-more-frequent-autovacuums-with-relallfroz.patchapplication/octet-stream; name=v1-0002-Trigger-more-frequent-autovacuums-with-relallfroz.patchDownload
From 6de3d9c7c1b1203a1b7680b74bef70fa7ab6b653 Mon Sep 17 00:00:00 2001
From: Melanie Plageman <melanieplageman@gmail.com>
Date: Fri, 4 Oct 2024 17:06:04 -0400
Subject: [PATCH v1 2/2] Trigger more frequent autovacuums with relallfrozen
Calculate the insert threshold for triggering an autovacuum of a
relation based on the number of unfrozen pages. By only considering the
"active" (unfrozen) portion of the table when calculating how many
tuples to add to the insert threshold, we can trigger more frequent
vacuums of insert-heavy tables and increase the chances of vacuuming
those pages when they still reside in shared buffers.
---
doc/src/sgml/config.sgml | 4 +--
src/backend/postmaster/autovacuum.c | 26 +++++++++++++++++--
src/backend/utils/misc/postgresql.conf.sample | 4 +--
3 files changed, 28 insertions(+), 6 deletions(-)
diff --git a/doc/src/sgml/config.sgml b/doc/src/sgml/config.sgml
index 934ef5e469..a303f06e4c 100644
--- a/doc/src/sgml/config.sgml
+++ b/doc/src/sgml/config.sgml
@@ -8683,10 +8683,10 @@ COPY postgres_log FROM '/full/path/to/logfile.csv' WITH csv;
</term>
<listitem>
<para>
- Specifies a fraction of the table size to add to
+ Specifies a fraction of the active (unfrozen) table size to add to
<varname>autovacuum_vacuum_insert_threshold</varname>
when deciding whether to trigger a <command>VACUUM</command>.
- The default is 0.2 (20% of table size).
+ The default is 0.2 (20% of active table size).
This parameter can only be set in the <filename>postgresql.conf</filename>
file or on the server command line;
but the setting can be overridden for individual tables by
diff --git a/src/backend/postmaster/autovacuum.c b/src/backend/postmaster/autovacuum.c
index dc3cf87aba..9bd96794ae 100644
--- a/src/backend/postmaster/autovacuum.c
+++ b/src/backend/postmaster/autovacuum.c
@@ -2922,7 +2922,12 @@ relation_needs_vacanalyze(Oid relid,
{
bool force_vacuum;
bool av_enabled;
- float4 reltuples; /* pg_class.reltuples */
+
+ /* From pg_class */
+ float4 reltuples;
+ int32 relpages;
+ int32 relallfrozen;
+ int32 relallvisible;
/* constants from reloptions or GUC variables */
int vac_base_thresh,
@@ -3030,6 +3035,11 @@ relation_needs_vacanalyze(Oid relid,
*/
if (PointerIsValid(tabentry) && AutoVacuumingActive())
{
+ float4 pcnt_unfrozen = 1;
+
+ relpages = classForm->relpages;
+ relallfrozen = classForm->relallfrozen;
+ relallvisible = classForm->relallvisible;
reltuples = classForm->reltuples;
vactuples = tabentry->dead_tuples;
instuples = tabentry->ins_since_vacuum;
@@ -3039,8 +3049,20 @@ relation_needs_vacanalyze(Oid relid,
if (reltuples < 0)
reltuples = 0;
+ if (reltuples == 0 || relpages < 0)
+ relpages = 0;
+
+ if (relallvisible > relpages)
+ relallvisible = relpages;
+
+ if (relallfrozen > relallvisible)
+ relallfrozen = relallvisible;
+
+ if (relpages > 0)
+ pcnt_unfrozen = 1 - ((float4) relallfrozen / relpages);
+
vacthresh = (float4) vac_base_thresh + vac_scale_factor * reltuples;
- vacinsthresh = (float4) vac_ins_base_thresh + vac_ins_scale_factor * reltuples;
+ vacinsthresh = (float4) vac_ins_base_thresh + vac_ins_scale_factor * reltuples * pcnt_unfrozen;
anlthresh = (float4) anl_base_thresh + anl_scale_factor * reltuples;
/*
diff --git a/src/backend/utils/misc/postgresql.conf.sample b/src/backend/utils/misc/postgresql.conf.sample
index 667e0dc40a..242155c423 100644
--- a/src/backend/utils/misc/postgresql.conf.sample
+++ b/src/backend/utils/misc/postgresql.conf.sample
@@ -669,8 +669,8 @@
#autovacuum_analyze_threshold = 50 # min number of row updates before
# analyze
#autovacuum_vacuum_scale_factor = 0.2 # fraction of table size before vacuum
-#autovacuum_vacuum_insert_scale_factor = 0.2 # fraction of inserts over table
- # size before insert vacuum
+#autovacuum_vacuum_insert_scale_factor = 0.2 # fraction of inserts over active
+ # table size before insert vacuum
#autovacuum_analyze_scale_factor = 0.1 # fraction of table size before analyze
#autovacuum_freeze_max_age = 200000000 # maximum XID age before forced vacuum
# (change requires restart)
--
2.45.2
v1-0001-Add-relallfrozen-to-pg_class.patchapplication/octet-stream; name=v1-0001-Add-relallfrozen-to-pg_class.patchDownload
From 564851f3d0450c604732ecf468ce46457d36d989 Mon Sep 17 00:00:00 2001
From: Melanie Plageman <melanieplageman@gmail.com>
Date: Fri, 4 Oct 2024 14:29:47 -0400
Subject: [PATCH v1 1/2] Add relallfrozen to pg_class
Add relallfrozen, an estimate of the number of pages marked all-frozen
in the visibility map.
pg_class already has relallvisible, an estimate of the number of pages
in the relation marked all-visible in the visibility map. This is used
primarily for planning.
relallfrozen, however, is useful for estimating the outstanding number
of all-visible but not all-frozen pages in the relation for the purposes
of scheduling manual VACUUMs and tuning vacuum freeze parameters.
In the future, this field could be used to trigger more frequent vacuums
on insert-focused workloads with significant volume of frozen data.
---
doc/src/sgml/catalogs.sgml | 15 ++++++++++++++
src/backend/access/heap/vacuumlazy.c | 17 ++++++++++++----
src/backend/catalog/heap.c | 2 ++
src/backend/catalog/index.c | 27 +++++++++++++++++--------
src/backend/commands/analyze.c | 12 +++++------
src/backend/commands/cluster.c | 5 +++++
src/backend/commands/vacuum.c | 6 ++++++
src/backend/statistics/relation_stats.c | 9 +++++++++
src/backend/utils/cache/relcache.c | 2 ++
src/include/catalog/pg_class.h | 3 +++
src/include/commands/vacuum.h | 1 +
11 files changed, 81 insertions(+), 18 deletions(-)
diff --git a/doc/src/sgml/catalogs.sgml b/doc/src/sgml/catalogs.sgml
index 964c819a02..174ef29ed6 100644
--- a/doc/src/sgml/catalogs.sgml
+++ b/doc/src/sgml/catalogs.sgml
@@ -2066,6 +2066,21 @@ SCRAM-SHA-256$<replaceable><iteration count></replaceable>:<replaceable>&l
</para></entry>
</row>
+ <row>
+ <entry role="catalog_table_entry"><para role="column_definition">
+ <structfield>relallfrozen</structfield> <type>int4</type>
+ </para>
+ <para>
+ Number of pages that are marked all-frozen in the table's
+ visibility map. This is only an estimate used for triggering autovacuums.
+ It is updated by <link linkend="sql-vacuum"><command>VACUUM</command></link>,
+ <link linkend="sql-analyze"><command>ANALYZE</command></link>, and a few DDL commands such as
+ <link linkend="sql-createindex"><command>CREATE INDEX</command></link>.
+ Every all-frozen page must also be marked all-visible.
+ </para></entry>
+ </row>
+
+
<row>
<entry role="catalog_table_entry"><para role="column_definition">
<structfield>reltoastrelid</structfield> <type>oid</type>
diff --git a/src/backend/access/heap/vacuumlazy.c b/src/backend/access/heap/vacuumlazy.c
index d82aa3d489..dff4cd08a9 100644
--- a/src/backend/access/heap/vacuumlazy.c
+++ b/src/backend/access/heap/vacuumlazy.c
@@ -303,7 +303,8 @@ heap_vacuum_rel(Relation rel, VacuumParams *params,
minmulti_updated;
BlockNumber orig_rel_pages,
new_rel_pages,
- new_rel_allvisible;
+ new_rel_allvisible,
+ new_rel_allfrozen;
PGRUsage ru0;
TimestampTz starttime = 0;
PgStat_Counter startreadtime = 0,
@@ -558,10 +559,17 @@ heap_vacuum_rel(Relation rel, VacuumParams *params,
* pg_class.relpages to
*/
new_rel_pages = vacrel->rel_pages; /* After possible rel truncation */
- visibilitymap_count(rel, &new_rel_allvisible, NULL);
+ visibilitymap_count(rel, &new_rel_allvisible, &new_rel_allfrozen);
if (new_rel_allvisible > new_rel_pages)
new_rel_allvisible = new_rel_pages;
+ /*
+ * Every block marked all-frozen in the VM must also be marked
+ * all-visible.
+ */
+ if (new_rel_allfrozen > new_rel_allvisible)
+ new_rel_allfrozen = new_rel_allvisible;
+
/*
* Now actually update rel's pg_class entry.
*
@@ -570,7 +578,8 @@ heap_vacuum_rel(Relation rel, VacuumParams *params,
* scan every page that isn't skipped using the visibility map.
*/
vac_update_relstats(rel, new_rel_pages, vacrel->new_live_tuples,
- new_rel_allvisible, vacrel->nindexes > 0,
+ new_rel_allvisible, new_rel_allfrozen,
+ vacrel->nindexes > 0,
vacrel->NewRelfrozenXid, vacrel->NewRelminMxid,
&frozenxid_updated, &minmulti_updated, false);
@@ -3100,7 +3109,7 @@ update_relstats_all_indexes(LVRelState *vacrel)
vac_update_relstats(indrel,
istat->num_pages,
istat->num_index_tuples,
- 0,
+ 0, 0,
false,
InvalidTransactionId,
InvalidMultiXactId,
diff --git a/src/backend/catalog/heap.c b/src/backend/catalog/heap.c
index 0078a12f26..d150d2b9a7 100644
--- a/src/backend/catalog/heap.c
+++ b/src/backend/catalog/heap.c
@@ -920,6 +920,7 @@ InsertPgClassTuple(Relation pg_class_desc,
values[Anum_pg_class_relpages - 1] = Int32GetDatum(rd_rel->relpages);
values[Anum_pg_class_reltuples - 1] = Float4GetDatum(rd_rel->reltuples);
values[Anum_pg_class_relallvisible - 1] = Int32GetDatum(rd_rel->relallvisible);
+ values[Anum_pg_class_relallfrozen - 1] = Int32GetDatum(rd_rel->relallfrozen);
values[Anum_pg_class_reltoastrelid - 1] = ObjectIdGetDatum(rd_rel->reltoastrelid);
values[Anum_pg_class_relhasindex - 1] = BoolGetDatum(rd_rel->relhasindex);
values[Anum_pg_class_relisshared - 1] = BoolGetDatum(rd_rel->relisshared);
@@ -990,6 +991,7 @@ AddNewRelationTuple(Relation pg_class_desc,
new_rel_reltup->relpages = 0;
new_rel_reltup->reltuples = -1;
new_rel_reltup->relallvisible = 0;
+ new_rel_reltup->relallfrozen = 0;
/* Sequences always have a known size */
if (relkind == RELKIND_SEQUENCE)
diff --git a/src/backend/catalog/index.c b/src/backend/catalog/index.c
index 12822d0b14..2386009a1d 100644
--- a/src/backend/catalog/index.c
+++ b/src/backend/catalog/index.c
@@ -2795,8 +2795,8 @@ FormIndexDatum(IndexInfo *indexInfo,
* hasindex: set relhasindex to this value
* reltuples: if >= 0, set reltuples to this value; else no change
*
- * If reltuples >= 0, relpages and relallvisible are also updated (using
- * RelationGetNumberOfBlocks() and visibilitymap_count()).
+ * If reltuples >= 0, relpages, relallvisible, and relallfrozen are also
+ * updated (using RelationGetNumberOfBlocks() and visibilitymap_count()).
*
* NOTE: an important side-effect of this operation is that an SI invalidation
* message is sent out to all backends --- including me --- causing relcache
@@ -2841,8 +2841,8 @@ index_update_stats(Relation rel,
* transaction could still fail before committing. Setting relhasindex
* true is safe even if there are no indexes (VACUUM will eventually fix
* it). And of course the new relpages and reltuples counts are correct
- * regardless. However, we don't want to change relpages (or
- * relallvisible) if the caller isn't providing an updated reltuples
+ * regardless. However, we don't want to change relpages (or relallvisible
+ * and relallfrozen) if the caller isn't providing an updated reltuples
* count, because that would bollix the reltuples/relpages ratio which is
* what's really important.
*/
@@ -2888,12 +2888,18 @@ index_update_stats(Relation rel,
if (reltuples >= 0 && !IsBinaryUpgrade)
{
BlockNumber relpages = RelationGetNumberOfBlocks(rel);
- BlockNumber relallvisible;
+ BlockNumber relallvisible = 0;
+ BlockNumber relallfrozen = 0;
+ /* don't bother for indexes */
if (rd_rel->relkind != RELKIND_INDEX)
- visibilitymap_count(rel, &relallvisible, NULL);
- else /* don't bother for indexes */
- relallvisible = 0;
+ {
+ visibilitymap_count(rel, &relallvisible, &relallfrozen);
+
+ /* Every all-frozen page must also be set all-visible in the VM */
+ if (relallfrozen > relallvisible)
+ relallfrozen = relallvisible;
+ }
if (rd_rel->relpages != (int32) relpages)
{
@@ -2910,6 +2916,11 @@ index_update_stats(Relation rel,
rd_rel->relallvisible = (int32) relallvisible;
dirty = true;
}
+ if (rd_rel->relallfrozen != (int32) relallfrozen)
+ {
+ rd_rel->relallfrozen = (int32) relallfrozen;
+ dirty = true;
+ }
}
/*
diff --git a/src/backend/commands/analyze.c b/src/backend/commands/analyze.c
index 38fb4c3ef2..0928592272 100644
--- a/src/backend/commands/analyze.c
+++ b/src/backend/commands/analyze.c
@@ -630,12 +630,11 @@ do_analyze_rel(Relation onerel, VacuumParams *params,
*/
if (!inh)
{
- BlockNumber relallvisible;
+ BlockNumber relallvisible = 0;
+ BlockNumber relallfrozen = 0;
if (RELKIND_HAS_STORAGE(onerel->rd_rel->relkind))
- visibilitymap_count(onerel, &relallvisible, NULL);
- else
- relallvisible = 0;
+ visibilitymap_count(onerel, &relallvisible, &relallfrozen);
/*
* Update pg_class for table relation. CCI first, in case acquirefunc
@@ -646,6 +645,7 @@ do_analyze_rel(Relation onerel, VacuumParams *params,
relpages,
totalrows,
relallvisible,
+ relallfrozen,
hasindex,
InvalidTransactionId,
InvalidMultiXactId,
@@ -662,7 +662,7 @@ do_analyze_rel(Relation onerel, VacuumParams *params,
vac_update_relstats(Irel[ind],
RelationGetNumberOfBlocks(Irel[ind]),
totalindexrows,
- 0,
+ 0, 0,
false,
InvalidTransactionId,
InvalidMultiXactId,
@@ -678,7 +678,7 @@ do_analyze_rel(Relation onerel, VacuumParams *params,
*/
CommandCounterIncrement();
vac_update_relstats(onerel, -1, totalrows,
- 0, hasindex, InvalidTransactionId,
+ 0, 0, hasindex, InvalidTransactionId,
InvalidMultiXactId,
NULL, NULL,
in_outer_xact);
diff --git a/src/backend/commands/cluster.c b/src/backend/commands/cluster.c
index 78f96789b0..4376355066 100644
--- a/src/backend/commands/cluster.c
+++ b/src/backend/commands/cluster.c
@@ -1224,6 +1224,7 @@ swap_relation_files(Oid r1, Oid r2, bool target_is_pg_class,
int32 swap_pages;
float4 swap_tuples;
int32 swap_allvisible;
+ int32 swap_allfrozen;
swap_pages = relform1->relpages;
relform1->relpages = relform2->relpages;
@@ -1236,6 +1237,10 @@ swap_relation_files(Oid r1, Oid r2, bool target_is_pg_class,
swap_allvisible = relform1->relallvisible;
relform1->relallvisible = relform2->relallvisible;
relform2->relallvisible = swap_allvisible;
+
+ swap_allfrozen = relform1->relallfrozen;
+ relform1->relallfrozen = relform2->relallfrozen;
+ relform2->relallfrozen = swap_allfrozen;
}
/*
diff --git a/src/backend/commands/vacuum.c b/src/backend/commands/vacuum.c
index ac8f5d9c25..7ed4df509c 100644
--- a/src/backend/commands/vacuum.c
+++ b/src/backend/commands/vacuum.c
@@ -1410,6 +1410,7 @@ void
vac_update_relstats(Relation relation,
BlockNumber num_pages, double num_tuples,
BlockNumber num_all_visible_pages,
+ BlockNumber num_all_frozen_pages,
bool hasindex, TransactionId frozenxid,
MultiXactId minmulti,
bool *frozenxid_updated, bool *minmulti_updated,
@@ -1459,6 +1460,11 @@ vac_update_relstats(Relation relation,
pgcform->relallvisible = (int32) num_all_visible_pages;
dirty = true;
}
+ if (pgcform->relallfrozen != (int32) num_all_frozen_pages)
+ {
+ pgcform->relallfrozen = (int32) num_all_frozen_pages;
+ dirty = true;
+ }
/* Apply DDL updates, but not inside an outer transaction (see above) */
diff --git a/src/backend/statistics/relation_stats.c b/src/backend/statistics/relation_stats.c
index 1a6d1640c3..1b1f02546f 100644
--- a/src/backend/statistics/relation_stats.c
+++ b/src/backend/statistics/relation_stats.c
@@ -160,6 +160,15 @@ relation_statistics_update(FunctionCallInfo fcinfo, int elevel)
replaces[ncols] = Anum_pg_class_relallvisible;
values[ncols] = Int32GetDatum(relallvisible);
ncols++;
+
+ /*
+ * If we are modifying relallvisible manually, it is not clear
+ * what relallfrozen value would make sense. Therefore, set it to
+ * NULL. It will be updated the next time these fields are
+ * updated.
+ */
+ replaces[ncols] = Anum_pg_class_relallfrozen;
+ nulls[ncols] = true;
}
}
diff --git a/src/backend/utils/cache/relcache.c b/src/backend/utils/cache/relcache.c
index c326f687eb..4bd9e10310 100644
--- a/src/backend/utils/cache/relcache.c
+++ b/src/backend/utils/cache/relcache.c
@@ -1936,6 +1936,7 @@ formrdesc(const char *relationName, Oid relationReltype,
relation->rd_rel->relpages = 0;
relation->rd_rel->reltuples = -1;
relation->rd_rel->relallvisible = 0;
+ relation->rd_rel->relallfrozen = 0;
relation->rd_rel->relkind = RELKIND_RELATION;
relation->rd_rel->relnatts = (int16) natts;
relation->rd_rel->relam = HEAP_TABLE_AM_OID;
@@ -3931,6 +3932,7 @@ RelationSetNewRelfilenumber(Relation relation, char persistence)
classform->relpages = 0; /* it's empty until further notice */
classform->reltuples = -1;
classform->relallvisible = 0;
+ classform->relallfrozen = 0;
}
classform->relfrozenxid = freezeXid;
classform->relminmxid = minmulti;
diff --git a/src/include/catalog/pg_class.h b/src/include/catalog/pg_class.h
index 0fc2c093b0..659ee68620 100644
--- a/src/include/catalog/pg_class.h
+++ b/src/include/catalog/pg_class.h
@@ -68,6 +68,9 @@ CATALOG(pg_class,1259,RelationRelationId) BKI_BOOTSTRAP BKI_ROWTYPE_OID(83,Relat
/* # of all-visible blocks (not always up-to-date) */
int32 relallvisible BKI_DEFAULT(0);
+ /* # of all-frozen blocks (not always up-to-date) */
+ int32 relallfrozen BKI_DEFAULT(0);
+
/* OID of toast table; 0 if none */
Oid reltoastrelid BKI_DEFAULT(0) BKI_LOOKUP_OPT(pg_class);
diff --git a/src/include/commands/vacuum.h b/src/include/commands/vacuum.h
index 759f9a87d3..c3fd2919e6 100644
--- a/src/include/commands/vacuum.h
+++ b/src/include/commands/vacuum.h
@@ -329,6 +329,7 @@ extern void vac_update_relstats(Relation relation,
BlockNumber num_pages,
double num_tuples,
BlockNumber num_all_visible_pages,
+ BlockNumber num_all_frozen_pages,
bool hasindex,
TransactionId frozenxid,
MultiXactId minmulti,
--
2.45.2
On Tue, Oct 22, 2024 at 3:12 PM Melanie Plageman
<melanieplageman@gmail.com> wrote:
The attached patch does this.
I realized that I broke relation_statistics_update(). Attached v2 is fixed.
I've estimated the unfrozen percentage of the table by adding a new
field to pg_class, relallfrozen, which is updated in the same places
as relallvisible.
While my relallfrozen column correctly appears in pg_class, I noticed
that it seems like catalog/pg_class_d.h did not have my column added
(this file is auto-generated), despite my adding relallfrozen to
catalog/pg_class.h. Is there something else I have to do when adding a
new column to pg_class?
At the end of the benchmark, the patched version of Postgres had
emitted twice as many FPIs as master.
This was meant to say the reverse -- _master_ did twice as many FPIs
as the patch
- Melanie
Attachments:
v2-0001-Add-relallfrozen-to-pg_class.patchtext/x-patch; charset=US-ASCII; name=v2-0001-Add-relallfrozen-to-pg_class.patchDownload
From 1bd8bbf4a62013e52180d17bc065eea826f784ff Mon Sep 17 00:00:00 2001
From: Melanie Plageman <melanieplageman@gmail.com>
Date: Fri, 4 Oct 2024 14:29:47 -0400
Subject: [PATCH v2 1/2] Add relallfrozen to pg_class
Add relallfrozen, an estimate of the number of pages marked all-frozen
in the visibility map.
pg_class already has relallvisible, an estimate of the number of pages
in the relation marked all-visible in the visibility map. This is used
primarily for planning.
relallfrozen, however, is useful for estimating the outstanding number
of all-visible but not all-frozen pages in the relation for the purposes
of scheduling manual VACUUMs and tuning vacuum freeze parameters.
In the future, this field could be used to trigger more frequent vacuums
on insert-focused workloads with significant volume of frozen data.
---
doc/src/sgml/catalogs.sgml | 15 ++++++++++++++
src/backend/access/heap/vacuumlazy.c | 17 ++++++++++++----
src/backend/catalog/heap.c | 2 ++
src/backend/catalog/index.c | 27 +++++++++++++++++--------
src/backend/commands/analyze.c | 12 +++++------
src/backend/commands/cluster.c | 5 +++++
src/backend/commands/vacuum.c | 6 ++++++
src/backend/statistics/relation_stats.c | 20 +++++++++++++++---
src/backend/utils/cache/relcache.c | 2 ++
src/include/catalog/catversion.h | 2 +-
src/include/catalog/pg_class.h | 3 +++
src/include/commands/vacuum.h | 1 +
12 files changed, 90 insertions(+), 22 deletions(-)
diff --git a/doc/src/sgml/catalogs.sgml b/doc/src/sgml/catalogs.sgml
index 964c819a02d..174ef29ed6d 100644
--- a/doc/src/sgml/catalogs.sgml
+++ b/doc/src/sgml/catalogs.sgml
@@ -2066,6 +2066,21 @@ SCRAM-SHA-256$<replaceable><iteration count></replaceable>:<replaceable>&l
</para></entry>
</row>
+ <row>
+ <entry role="catalog_table_entry"><para role="column_definition">
+ <structfield>relallfrozen</structfield> <type>int4</type>
+ </para>
+ <para>
+ Number of pages that are marked all-frozen in the table's
+ visibility map. This is only an estimate used for triggering autovacuums.
+ It is updated by <link linkend="sql-vacuum"><command>VACUUM</command></link>,
+ <link linkend="sql-analyze"><command>ANALYZE</command></link>, and a few DDL commands such as
+ <link linkend="sql-createindex"><command>CREATE INDEX</command></link>.
+ Every all-frozen page must also be marked all-visible.
+ </para></entry>
+ </row>
+
+
<row>
<entry role="catalog_table_entry"><para role="column_definition">
<structfield>reltoastrelid</structfield> <type>oid</type>
diff --git a/src/backend/access/heap/vacuumlazy.c b/src/backend/access/heap/vacuumlazy.c
index d82aa3d4896..dff4cd08a99 100644
--- a/src/backend/access/heap/vacuumlazy.c
+++ b/src/backend/access/heap/vacuumlazy.c
@@ -303,7 +303,8 @@ heap_vacuum_rel(Relation rel, VacuumParams *params,
minmulti_updated;
BlockNumber orig_rel_pages,
new_rel_pages,
- new_rel_allvisible;
+ new_rel_allvisible,
+ new_rel_allfrozen;
PGRUsage ru0;
TimestampTz starttime = 0;
PgStat_Counter startreadtime = 0,
@@ -558,10 +559,17 @@ heap_vacuum_rel(Relation rel, VacuumParams *params,
* pg_class.relpages to
*/
new_rel_pages = vacrel->rel_pages; /* After possible rel truncation */
- visibilitymap_count(rel, &new_rel_allvisible, NULL);
+ visibilitymap_count(rel, &new_rel_allvisible, &new_rel_allfrozen);
if (new_rel_allvisible > new_rel_pages)
new_rel_allvisible = new_rel_pages;
+ /*
+ * Every block marked all-frozen in the VM must also be marked
+ * all-visible.
+ */
+ if (new_rel_allfrozen > new_rel_allvisible)
+ new_rel_allfrozen = new_rel_allvisible;
+
/*
* Now actually update rel's pg_class entry.
*
@@ -570,7 +578,8 @@ heap_vacuum_rel(Relation rel, VacuumParams *params,
* scan every page that isn't skipped using the visibility map.
*/
vac_update_relstats(rel, new_rel_pages, vacrel->new_live_tuples,
- new_rel_allvisible, vacrel->nindexes > 0,
+ new_rel_allvisible, new_rel_allfrozen,
+ vacrel->nindexes > 0,
vacrel->NewRelfrozenXid, vacrel->NewRelminMxid,
&frozenxid_updated, &minmulti_updated, false);
@@ -3100,7 +3109,7 @@ update_relstats_all_indexes(LVRelState *vacrel)
vac_update_relstats(indrel,
istat->num_pages,
istat->num_index_tuples,
- 0,
+ 0, 0,
false,
InvalidTransactionId,
InvalidMultiXactId,
diff --git a/src/backend/catalog/heap.c b/src/backend/catalog/heap.c
index 0078a12f26e..d150d2b9a72 100644
--- a/src/backend/catalog/heap.c
+++ b/src/backend/catalog/heap.c
@@ -920,6 +920,7 @@ InsertPgClassTuple(Relation pg_class_desc,
values[Anum_pg_class_relpages - 1] = Int32GetDatum(rd_rel->relpages);
values[Anum_pg_class_reltuples - 1] = Float4GetDatum(rd_rel->reltuples);
values[Anum_pg_class_relallvisible - 1] = Int32GetDatum(rd_rel->relallvisible);
+ values[Anum_pg_class_relallfrozen - 1] = Int32GetDatum(rd_rel->relallfrozen);
values[Anum_pg_class_reltoastrelid - 1] = ObjectIdGetDatum(rd_rel->reltoastrelid);
values[Anum_pg_class_relhasindex - 1] = BoolGetDatum(rd_rel->relhasindex);
values[Anum_pg_class_relisshared - 1] = BoolGetDatum(rd_rel->relisshared);
@@ -990,6 +991,7 @@ AddNewRelationTuple(Relation pg_class_desc,
new_rel_reltup->relpages = 0;
new_rel_reltup->reltuples = -1;
new_rel_reltup->relallvisible = 0;
+ new_rel_reltup->relallfrozen = 0;
/* Sequences always have a known size */
if (relkind == RELKIND_SEQUENCE)
diff --git a/src/backend/catalog/index.c b/src/backend/catalog/index.c
index 12822d0b140..2386009a1d7 100644
--- a/src/backend/catalog/index.c
+++ b/src/backend/catalog/index.c
@@ -2795,8 +2795,8 @@ FormIndexDatum(IndexInfo *indexInfo,
* hasindex: set relhasindex to this value
* reltuples: if >= 0, set reltuples to this value; else no change
*
- * If reltuples >= 0, relpages and relallvisible are also updated (using
- * RelationGetNumberOfBlocks() and visibilitymap_count()).
+ * If reltuples >= 0, relpages, relallvisible, and relallfrozen are also
+ * updated (using RelationGetNumberOfBlocks() and visibilitymap_count()).
*
* NOTE: an important side-effect of this operation is that an SI invalidation
* message is sent out to all backends --- including me --- causing relcache
@@ -2841,8 +2841,8 @@ index_update_stats(Relation rel,
* transaction could still fail before committing. Setting relhasindex
* true is safe even if there are no indexes (VACUUM will eventually fix
* it). And of course the new relpages and reltuples counts are correct
- * regardless. However, we don't want to change relpages (or
- * relallvisible) if the caller isn't providing an updated reltuples
+ * regardless. However, we don't want to change relpages (or relallvisible
+ * and relallfrozen) if the caller isn't providing an updated reltuples
* count, because that would bollix the reltuples/relpages ratio which is
* what's really important.
*/
@@ -2888,12 +2888,18 @@ index_update_stats(Relation rel,
if (reltuples >= 0 && !IsBinaryUpgrade)
{
BlockNumber relpages = RelationGetNumberOfBlocks(rel);
- BlockNumber relallvisible;
+ BlockNumber relallvisible = 0;
+ BlockNumber relallfrozen = 0;
+ /* don't bother for indexes */
if (rd_rel->relkind != RELKIND_INDEX)
- visibilitymap_count(rel, &relallvisible, NULL);
- else /* don't bother for indexes */
- relallvisible = 0;
+ {
+ visibilitymap_count(rel, &relallvisible, &relallfrozen);
+
+ /* Every all-frozen page must also be set all-visible in the VM */
+ if (relallfrozen > relallvisible)
+ relallfrozen = relallvisible;
+ }
if (rd_rel->relpages != (int32) relpages)
{
@@ -2910,6 +2916,11 @@ index_update_stats(Relation rel,
rd_rel->relallvisible = (int32) relallvisible;
dirty = true;
}
+ if (rd_rel->relallfrozen != (int32) relallfrozen)
+ {
+ rd_rel->relallfrozen = (int32) relallfrozen;
+ dirty = true;
+ }
}
/*
diff --git a/src/backend/commands/analyze.c b/src/backend/commands/analyze.c
index 38fb4c3ef23..0928592272e 100644
--- a/src/backend/commands/analyze.c
+++ b/src/backend/commands/analyze.c
@@ -630,12 +630,11 @@ do_analyze_rel(Relation onerel, VacuumParams *params,
*/
if (!inh)
{
- BlockNumber relallvisible;
+ BlockNumber relallvisible = 0;
+ BlockNumber relallfrozen = 0;
if (RELKIND_HAS_STORAGE(onerel->rd_rel->relkind))
- visibilitymap_count(onerel, &relallvisible, NULL);
- else
- relallvisible = 0;
+ visibilitymap_count(onerel, &relallvisible, &relallfrozen);
/*
* Update pg_class for table relation. CCI first, in case acquirefunc
@@ -646,6 +645,7 @@ do_analyze_rel(Relation onerel, VacuumParams *params,
relpages,
totalrows,
relallvisible,
+ relallfrozen,
hasindex,
InvalidTransactionId,
InvalidMultiXactId,
@@ -662,7 +662,7 @@ do_analyze_rel(Relation onerel, VacuumParams *params,
vac_update_relstats(Irel[ind],
RelationGetNumberOfBlocks(Irel[ind]),
totalindexrows,
- 0,
+ 0, 0,
false,
InvalidTransactionId,
InvalidMultiXactId,
@@ -678,7 +678,7 @@ do_analyze_rel(Relation onerel, VacuumParams *params,
*/
CommandCounterIncrement();
vac_update_relstats(onerel, -1, totalrows,
- 0, hasindex, InvalidTransactionId,
+ 0, 0, hasindex, InvalidTransactionId,
InvalidMultiXactId,
NULL, NULL,
in_outer_xact);
diff --git a/src/backend/commands/cluster.c b/src/backend/commands/cluster.c
index 78f96789b0e..43763550668 100644
--- a/src/backend/commands/cluster.c
+++ b/src/backend/commands/cluster.c
@@ -1224,6 +1224,7 @@ swap_relation_files(Oid r1, Oid r2, bool target_is_pg_class,
int32 swap_pages;
float4 swap_tuples;
int32 swap_allvisible;
+ int32 swap_allfrozen;
swap_pages = relform1->relpages;
relform1->relpages = relform2->relpages;
@@ -1236,6 +1237,10 @@ swap_relation_files(Oid r1, Oid r2, bool target_is_pg_class,
swap_allvisible = relform1->relallvisible;
relform1->relallvisible = relform2->relallvisible;
relform2->relallvisible = swap_allvisible;
+
+ swap_allfrozen = relform1->relallfrozen;
+ relform1->relallfrozen = relform2->relallfrozen;
+ relform2->relallfrozen = swap_allfrozen;
}
/*
diff --git a/src/backend/commands/vacuum.c b/src/backend/commands/vacuum.c
index ac8f5d9c259..7ed4df509c5 100644
--- a/src/backend/commands/vacuum.c
+++ b/src/backend/commands/vacuum.c
@@ -1410,6 +1410,7 @@ void
vac_update_relstats(Relation relation,
BlockNumber num_pages, double num_tuples,
BlockNumber num_all_visible_pages,
+ BlockNumber num_all_frozen_pages,
bool hasindex, TransactionId frozenxid,
MultiXactId minmulti,
bool *frozenxid_updated, bool *minmulti_updated,
@@ -1459,6 +1460,11 @@ vac_update_relstats(Relation relation,
pgcform->relallvisible = (int32) num_all_visible_pages;
dirty = true;
}
+ if (pgcform->relallfrozen != (int32) num_all_frozen_pages)
+ {
+ pgcform->relallfrozen = (int32) num_all_frozen_pages;
+ dirty = true;
+ }
/* Apply DDL updates, but not inside an outer transaction (see above) */
diff --git a/src/backend/statistics/relation_stats.c b/src/backend/statistics/relation_stats.c
index b1eb8a9bbaf..bc7092dc1ca 100644
--- a/src/backend/statistics/relation_stats.c
+++ b/src/backend/statistics/relation_stats.c
@@ -54,6 +54,10 @@ static bool relation_statistics_update(FunctionCallInfo fcinfo, int elevel);
/*
* Internal function for modifying statistics for a relation.
+ *
+ * Up to four pg_class columns may be updated even though only three relation
+ * statistics may be modified; relallfrozen is always set to -1 when
+ * relallvisible is updated manually.
*/
static bool
relation_statistics_update(FunctionCallInfo fcinfo, int elevel)
@@ -62,9 +66,9 @@ relation_statistics_update(FunctionCallInfo fcinfo, int elevel)
Relation crel;
HeapTuple ctup;
Form_pg_class pgcform;
- int replaces[3] = {0};
- Datum values[3] = {0};
- bool nulls[3] = {0};
+ int replaces[4] = {0};
+ Datum values[4] = {0};
+ bool nulls[4] = {0};
int ncols = 0;
TupleDesc tupdesc;
HeapTuple newtup;
@@ -160,6 +164,16 @@ relation_statistics_update(FunctionCallInfo fcinfo, int elevel)
replaces[ncols] = Anum_pg_class_relallvisible;
values[ncols] = Int32GetDatum(relallvisible);
ncols++;
+
+ /*
+ * If we are modifying relallvisible manually, it is not clear
+ * what relallfrozen value would make sense. Therefore, set it to
+ * -1, or unknown. It will be updated the next time these fields
+ * are updated.
+ */
+ replaces[ncols] = Anum_pg_class_relallfrozen;
+ values[ncols] = Int32GetDatum(-1);
+ ncols++;
}
}
diff --git a/src/backend/utils/cache/relcache.c b/src/backend/utils/cache/relcache.c
index c326f687eb4..4bd9e10310c 100644
--- a/src/backend/utils/cache/relcache.c
+++ b/src/backend/utils/cache/relcache.c
@@ -1936,6 +1936,7 @@ formrdesc(const char *relationName, Oid relationReltype,
relation->rd_rel->relpages = 0;
relation->rd_rel->reltuples = -1;
relation->rd_rel->relallvisible = 0;
+ relation->rd_rel->relallfrozen = 0;
relation->rd_rel->relkind = RELKIND_RELATION;
relation->rd_rel->relnatts = (int16) natts;
relation->rd_rel->relam = HEAP_TABLE_AM_OID;
@@ -3931,6 +3932,7 @@ RelationSetNewRelfilenumber(Relation relation, char persistence)
classform->relpages = 0; /* it's empty until further notice */
classform->reltuples = -1;
classform->relallvisible = 0;
+ classform->relallfrozen = 0;
}
classform->relfrozenxid = freezeXid;
classform->relminmxid = minmulti;
diff --git a/src/include/catalog/catversion.h b/src/include/catalog/catversion.h
index 391bf04bf5d..6d241f449bb 100644
--- a/src/include/catalog/catversion.h
+++ b/src/include/catalog/catversion.h
@@ -57,6 +57,6 @@
*/
/* yyyymmddN */
-#define CATALOG_VERSION_NO 202410222
+#define CATALOG_VERSION_NO 202410223
#endif
diff --git a/src/include/catalog/pg_class.h b/src/include/catalog/pg_class.h
index 0fc2c093b0d..b915bef9aa5 100644
--- a/src/include/catalog/pg_class.h
+++ b/src/include/catalog/pg_class.h
@@ -68,6 +68,9 @@ CATALOG(pg_class,1259,RelationRelationId) BKI_BOOTSTRAP BKI_ROWTYPE_OID(83,Relat
/* # of all-visible blocks (not always up-to-date) */
int32 relallvisible BKI_DEFAULT(0);
+ /* # of all-frozen blocks (not always up-to-date; -1 means "unknown") */
+ int32 relallfrozen BKI_DEFAULT(0);
+
/* OID of toast table; 0 if none */
Oid reltoastrelid BKI_DEFAULT(0) BKI_LOOKUP_OPT(pg_class);
diff --git a/src/include/commands/vacuum.h b/src/include/commands/vacuum.h
index 759f9a87d38..c3fd2919e64 100644
--- a/src/include/commands/vacuum.h
+++ b/src/include/commands/vacuum.h
@@ -329,6 +329,7 @@ extern void vac_update_relstats(Relation relation,
BlockNumber num_pages,
double num_tuples,
BlockNumber num_all_visible_pages,
+ BlockNumber num_all_frozen_pages,
bool hasindex,
TransactionId frozenxid,
MultiXactId minmulti,
--
2.34.1
v2-0002-Trigger-more-frequent-autovacuums-with-relallfroz.patchtext/x-patch; charset=US-ASCII; name=v2-0002-Trigger-more-frequent-autovacuums-with-relallfroz.patchDownload
From e29e41ac11b614aafb58412e042c50f37e33ef06 Mon Sep 17 00:00:00 2001
From: Melanie Plageman <melanieplageman@gmail.com>
Date: Fri, 4 Oct 2024 17:06:04 -0400
Subject: [PATCH v2 2/2] Trigger more frequent autovacuums with relallfrozen
Calculate the insert threshold for triggering an autovacuum of a
relation based on the number of unfrozen pages. By only considering the
"active" (unfrozen) portion of the table when calculating how many
tuples to add to the insert threshold, we can trigger more frequent
vacuums of insert-heavy tables and increase the chances of vacuuming
those pages when they still reside in shared buffers.
---
doc/src/sgml/config.sgml | 4 +--
src/backend/postmaster/autovacuum.c | 26 +++++++++++++++++--
src/backend/utils/misc/postgresql.conf.sample | 4 +--
3 files changed, 28 insertions(+), 6 deletions(-)
diff --git a/doc/src/sgml/config.sgml b/doc/src/sgml/config.sgml
index 934ef5e4691..a303f06e4c9 100644
--- a/doc/src/sgml/config.sgml
+++ b/doc/src/sgml/config.sgml
@@ -8683,10 +8683,10 @@ COPY postgres_log FROM '/full/path/to/logfile.csv' WITH csv;
</term>
<listitem>
<para>
- Specifies a fraction of the table size to add to
+ Specifies a fraction of the active (unfrozen) table size to add to
<varname>autovacuum_vacuum_insert_threshold</varname>
when deciding whether to trigger a <command>VACUUM</command>.
- The default is 0.2 (20% of table size).
+ The default is 0.2 (20% of active table size).
This parameter can only be set in the <filename>postgresql.conf</filename>
file or on the server command line;
but the setting can be overridden for individual tables by
diff --git a/src/backend/postmaster/autovacuum.c b/src/backend/postmaster/autovacuum.c
index dc3cf87abab..9bd96794ae9 100644
--- a/src/backend/postmaster/autovacuum.c
+++ b/src/backend/postmaster/autovacuum.c
@@ -2922,7 +2922,12 @@ relation_needs_vacanalyze(Oid relid,
{
bool force_vacuum;
bool av_enabled;
- float4 reltuples; /* pg_class.reltuples */
+
+ /* From pg_class */
+ float4 reltuples;
+ int32 relpages;
+ int32 relallfrozen;
+ int32 relallvisible;
/* constants from reloptions or GUC variables */
int vac_base_thresh,
@@ -3030,6 +3035,11 @@ relation_needs_vacanalyze(Oid relid,
*/
if (PointerIsValid(tabentry) && AutoVacuumingActive())
{
+ float4 pcnt_unfrozen = 1;
+
+ relpages = classForm->relpages;
+ relallfrozen = classForm->relallfrozen;
+ relallvisible = classForm->relallvisible;
reltuples = classForm->reltuples;
vactuples = tabentry->dead_tuples;
instuples = tabentry->ins_since_vacuum;
@@ -3039,8 +3049,20 @@ relation_needs_vacanalyze(Oid relid,
if (reltuples < 0)
reltuples = 0;
+ if (reltuples == 0 || relpages < 0)
+ relpages = 0;
+
+ if (relallvisible > relpages)
+ relallvisible = relpages;
+
+ if (relallfrozen > relallvisible)
+ relallfrozen = relallvisible;
+
+ if (relpages > 0)
+ pcnt_unfrozen = 1 - ((float4) relallfrozen / relpages);
+
vacthresh = (float4) vac_base_thresh + vac_scale_factor * reltuples;
- vacinsthresh = (float4) vac_ins_base_thresh + vac_ins_scale_factor * reltuples;
+ vacinsthresh = (float4) vac_ins_base_thresh + vac_ins_scale_factor * reltuples * pcnt_unfrozen;
anlthresh = (float4) anl_base_thresh + anl_scale_factor * reltuples;
/*
diff --git a/src/backend/utils/misc/postgresql.conf.sample b/src/backend/utils/misc/postgresql.conf.sample
index 667e0dc40a2..242155c4230 100644
--- a/src/backend/utils/misc/postgresql.conf.sample
+++ b/src/backend/utils/misc/postgresql.conf.sample
@@ -669,8 +669,8 @@
#autovacuum_analyze_threshold = 50 # min number of row updates before
# analyze
#autovacuum_vacuum_scale_factor = 0.2 # fraction of table size before vacuum
-#autovacuum_vacuum_insert_scale_factor = 0.2 # fraction of inserts over table
- # size before insert vacuum
+#autovacuum_vacuum_insert_scale_factor = 0.2 # fraction of inserts over active
+ # table size before insert vacuum
#autovacuum_analyze_scale_factor = 0.1 # fraction of table size before analyze
#autovacuum_freeze_max_age = 200000000 # maximum XID age before forced vacuum
# (change requires restart)
--
2.34.1
I really appreciate all the work to make vacuum better. Anything that helps
our problem of autovacuum not scaling well for large tables is a win.
I'm not overly familiar with this part of the code base, but here are some
questions/ideas:
+ /*
+ * Every block marked all-frozen in the VM must also be marked
+ * all-visible.
+ */
+ if (new_rel_allfrozen > new_rel_allvisible)
+ new_rel_allfrozen = new_rel_allvisible;
+
Maybe tweak either the comment, or the code, as I read that comment as
meaning:
if (new_rel_allfrozen > new_rel_allvisible)
new_ral_allvisible = new_rel_allfrozen;
+ /*
+ * If we are modifying relallvisible manually, it
is not clear
+ * what relallfrozen value would make sense.
Therefore, set it to
+ * -1, or unknown. It will be updated the next time
these fields
+ * are updated.
+ */
+ replaces[ncols] = Anum_pg_class_relallfrozen;
+ values[ncols] = Int32GetDatum(-1);
Do we need some extra checks later on when we are actually using this to
prevent negative numbers in the calculations? It's only going to make
pcnt_unfrozen something like 1.0001 but still might want to skip that.
In autovacuum.c, seems we could simplify some of the logic there to this?:
if (relpages > 0 && reltuples > 0) {
relallfrozen = classForm->relallfrozen;
relallvisible = classForm->relallvisible;
if (relallvisible > relpages)
relallvisible = relpages;
if (relallfrozen > relallvisible)
relallfrozen = relallvisible;
pcnt_unfrozen = 1 - ((float4) relallfrozen / relpages);
}
vacinsthresh = (float4) vac_ins_base_thresh + vac_ins_scale_factor *
reltuples * pcnt_unfrozen;
Again, I'm not clear under what circumstances will relallvisible > relpages?
Cheers,
Greg
Thanks for the review!
On Thu, Oct 24, 2024 at 3:51 PM Greg Sabino Mullane <htamfids@gmail.com> wrote:
I really appreciate all the work to make vacuum better. Anything that helps our problem of autovacuum not scaling well for large tables is a win.
I'm not overly familiar with this part of the code base, but here are some questions/ideas:
+ /* + * Every block marked all-frozen in the VM must also be marked + * all-visible. + */ + if (new_rel_allfrozen > new_rel_allvisible) + new_rel_allfrozen = new_rel_allvisible; +Maybe tweak either the comment, or the code, as I read that comment as meaning:
if (new_rel_allfrozen > new_rel_allvisible)
new_ral_allvisible = new_rel_allfrozen;
I've updated it. An all-frozen block must also be all-visible. But not
all-visible blocks are all-frozen
+ /* + * If we are modifying relallvisible manually, it is not clear + * what relallfrozen value would make sense. Therefore, set it to + * -1, or unknown. It will be updated the next time these fields + * are updated. + */ + replaces[ncols] = Anum_pg_class_relallfrozen; + values[ncols] = Int32GetDatum(-1);Do we need some extra checks later on when we are actually using this to prevent negative numbers in the calculations? It's only going to make pcnt_unfrozen something like 1.0001 but still might want to skip that.
Great point! I've added this
In autovacuum.c, seems we could simplify some of the logic there to this?:
if (relpages > 0 && reltuples > 0) {
relallfrozen = classForm->relallfrozen;
relallvisible = classForm->relallvisible;if (relallvisible > relpages)
relallvisible = relpages;if (relallfrozen > relallvisible)
relallfrozen = relallvisible;pcnt_unfrozen = 1 - ((float4) relallfrozen / relpages);
}
vacinsthresh = (float4) vac_ins_base_thresh + vac_ins_scale_factor * reltuples * pcnt_unfrozen;
I've done something similar to this in attached v2.
Again, I'm not clear under what circumstances will relallvisible > relpages?
I think this is mostly if someone manually updated the relation stats,
so we clamp it for safety.
- Melanie
Attachments:
v3-0002-Trigger-more-frequent-autovacuums-with-relallfroz.patchtext/x-patch; charset=US-ASCII; name=v3-0002-Trigger-more-frequent-autovacuums-with-relallfroz.patchDownload
From c2e29150e923f9782ce24a7a4e7d6f2d7445b543 Mon Sep 17 00:00:00 2001
From: Melanie Plageman <melanieplageman@gmail.com>
Date: Fri, 4 Oct 2024 17:06:04 -0400
Subject: [PATCH v3 2/2] Trigger more frequent autovacuums with relallfrozen
Calculate the insert threshold for triggering an autovacuum of a
relation based on the number of unfrozen pages. By only considering the
"active" (unfrozen) portion of the table when calculating how many
tuples to add to the insert threshold, we can trigger more frequent
vacuums of insert-heavy tables and increase the chances of vacuuming
those pages when they still reside in shared buffers.
Author: Melanie Plageman
Reviewed-by: Greg Sabino Mullane
---
doc/src/sgml/config.sgml | 4 +-
src/backend/postmaster/autovacuum.c | 37 ++++++++++++++++++-
src/backend/utils/misc/postgresql.conf.sample | 4 +-
3 files changed, 39 insertions(+), 6 deletions(-)
diff --git a/doc/src/sgml/config.sgml b/doc/src/sgml/config.sgml
index dc401087dc6..3bd22f7f1e7 100644
--- a/doc/src/sgml/config.sgml
+++ b/doc/src/sgml/config.sgml
@@ -8710,10 +8710,10 @@ COPY postgres_log FROM '/full/path/to/logfile.csv' WITH csv;
</term>
<listitem>
<para>
- Specifies a fraction of the table size to add to
+ Specifies a fraction of the active (unfrozen) table size to add to
<varname>autovacuum_vacuum_insert_threshold</varname>
when deciding whether to trigger a <command>VACUUM</command>.
- The default is 0.2 (20% of table size).
+ The default is 0.2 (20% of active table size).
This parameter can only be set in the <filename>postgresql.conf</filename>
file or on the server command line;
but the setting can be overridden for individual tables by
diff --git a/src/backend/postmaster/autovacuum.c b/src/backend/postmaster/autovacuum.c
index dc3cf87abab..364b46f672d 100644
--- a/src/backend/postmaster/autovacuum.c
+++ b/src/backend/postmaster/autovacuum.c
@@ -2922,7 +2922,12 @@ relation_needs_vacanalyze(Oid relid,
{
bool force_vacuum;
bool av_enabled;
- float4 reltuples; /* pg_class.reltuples */
+
+ /* From pg_class */
+ float4 reltuples;
+ int32 relpages;
+ int32 relallfrozen;
+ int32 relallvisible;
/* constants from reloptions or GUC variables */
int vac_base_thresh,
@@ -3030,6 +3035,10 @@ relation_needs_vacanalyze(Oid relid,
*/
if (PointerIsValid(tabentry) && AutoVacuumingActive())
{
+ float4 pcnt_unfrozen = 1;
+
+ relpages = classForm->relpages;
+ relallfrozen = classForm->relallfrozen;
reltuples = classForm->reltuples;
vactuples = tabentry->dead_tuples;
instuples = tabentry->ins_since_vacuum;
@@ -3039,8 +3048,32 @@ relation_needs_vacanalyze(Oid relid,
if (reltuples < 0)
reltuples = 0;
+ /*
+ * If the table has been vacuumed and we have reliable data for
+ * relallfrozen and relallvisible, calculate the unfrozen percentage
+ * of the table to modify insert scale factor. This helps us decide
+ * whether or not to vacuum an insert-heavy table based on the number
+ * of inserts to the "active" part of the table.
+ *
+ * If relallfrozen is -1, that means relallvisible was updated
+ * manually and we can't rely on relallfrozen.
+ */
+ if (relpages > 0 && reltuples > 0 && relallfrozen > -1)
+ {
+ relallvisible = classForm->relallvisible;
+
+ if (relallvisible > relpages)
+ relallvisible = relpages;
+
+ if (relallfrozen > relallvisible)
+ relallfrozen = relallvisible;
+
+ pcnt_unfrozen = 1 - ((float4) relallfrozen / relpages);
+ }
+
vacthresh = (float4) vac_base_thresh + vac_scale_factor * reltuples;
- vacinsthresh = (float4) vac_ins_base_thresh + vac_ins_scale_factor * reltuples;
+ vacinsthresh = (float4) vac_ins_base_thresh +
+ vac_ins_scale_factor * reltuples * pcnt_unfrozen;
anlthresh = (float4) anl_base_thresh + anl_scale_factor * reltuples;
/*
diff --git a/src/backend/utils/misc/postgresql.conf.sample b/src/backend/utils/misc/postgresql.conf.sample
index 39a3ac23127..a66f16e838a 100644
--- a/src/backend/utils/misc/postgresql.conf.sample
+++ b/src/backend/utils/misc/postgresql.conf.sample
@@ -670,8 +670,8 @@
#autovacuum_analyze_threshold = 50 # min number of row updates before
# analyze
#autovacuum_vacuum_scale_factor = 0.2 # fraction of table size before vacuum
-#autovacuum_vacuum_insert_scale_factor = 0.2 # fraction of inserts over table
- # size before insert vacuum
+#autovacuum_vacuum_insert_scale_factor = 0.2 # fraction of inserts over active
+ # table size before insert vacuum
#autovacuum_analyze_scale_factor = 0.1 # fraction of table size before analyze
#autovacuum_freeze_max_age = 200000000 # maximum XID age before forced vacuum
# (change requires restart)
--
2.34.1
v3-0001-Add-relallfrozen-to-pg_class.patchtext/x-patch; charset=US-ASCII; name=v3-0001-Add-relallfrozen-to-pg_class.patchDownload
From caab36b29b9a9e2582283279d2e9b0fa404307ae Mon Sep 17 00:00:00 2001
From: Melanie Plageman <melanieplageman@gmail.com>
Date: Fri, 25 Oct 2024 10:43:39 -0400
Subject: [PATCH v3 1/2] Add relallfrozen to pg_class
Add relallfrozen, an estimate of the number of pages marked all-frozen
in the visibility map.
pg_class already has relallvisible, an estimate of the number of pages
in the relation marked all-visible in the visibility map. This is used
primarily for planning.
relallfrozen, however, is useful for estimating the outstanding number
of all-visible but not all-frozen pages in the relation for the purposes
of scheduling manual VACUUMs and tuning vacuum freeze parameters.
In the future, this field could be used to trigger more frequent vacuums
on insert-focused workloads with significant volume of frozen data.
Author: Melanie Plageman
Reviewed-by: Greg Sabino Mullane
---
doc/src/sgml/catalogs.sgml | 20 ++++++++++++++++++
src/backend/access/heap/vacuumlazy.c | 17 ++++++++++++----
src/backend/catalog/heap.c | 2 ++
src/backend/catalog/index.c | 27 +++++++++++++++++--------
src/backend/commands/analyze.c | 12 +++++------
src/backend/commands/cluster.c | 5 +++++
src/backend/commands/vacuum.c | 6 ++++++
src/backend/statistics/relation_stats.c | 20 +++++++++++++++---
src/backend/utils/cache/relcache.c | 2 ++
src/include/catalog/catversion.h | 2 +-
src/include/catalog/pg_class.h | 3 +++
src/include/commands/vacuum.h | 1 +
12 files changed, 95 insertions(+), 22 deletions(-)
diff --git a/doc/src/sgml/catalogs.sgml b/doc/src/sgml/catalogs.sgml
index 964c819a02d..392a1f71eb0 100644
--- a/doc/src/sgml/catalogs.sgml
+++ b/doc/src/sgml/catalogs.sgml
@@ -2066,6 +2066,26 @@ SCRAM-SHA-256$<replaceable><iteration count></replaceable>:<replaceable>&l
</para></entry>
</row>
+ <row>
+ <entry role="catalog_table_entry"><para role="column_definition">
+ <structfield>relallfrozen</structfield> <type>int4</type>
+ </para>
+ <para>
+ Number of pages that are marked all-frozen in the table's visibility
+ map. This is only an estimate used for triggering autovacuums. It is
+ updated by <link linkend="sql-vacuum"><command>VACUUM</command></link>,
+ <link linkend="sql-analyze"><command>ANALYZE</command></link>,
+ and a few DDL commands such as
+ <link linkend="sql-createindex"><command>CREATE INDEX</command></link>.
+ <structfield>relallfrozen</structfield> must be less than or equal to
+ <strutfield>relallvisible</structfield> as an all-frozen page must be
+ all-visible. If <structfield>relallvisible</structfield> was updated
+ manually, <structfield>relallfrozen</structfield> will be -1 until the
+ next time they are updated.
+ </para></entry>
+ </row>
+
+
<row>
<entry role="catalog_table_entry"><para role="column_definition">
<structfield>reltoastrelid</structfield> <type>oid</type>
diff --git a/src/backend/access/heap/vacuumlazy.c b/src/backend/access/heap/vacuumlazy.c
index d82aa3d4896..776d1673bbb 100644
--- a/src/backend/access/heap/vacuumlazy.c
+++ b/src/backend/access/heap/vacuumlazy.c
@@ -303,7 +303,8 @@ heap_vacuum_rel(Relation rel, VacuumParams *params,
minmulti_updated;
BlockNumber orig_rel_pages,
new_rel_pages,
- new_rel_allvisible;
+ new_rel_allvisible,
+ new_rel_allfrozen;
PGRUsage ru0;
TimestampTz starttime = 0;
PgStat_Counter startreadtime = 0,
@@ -558,10 +559,17 @@ heap_vacuum_rel(Relation rel, VacuumParams *params,
* pg_class.relpages to
*/
new_rel_pages = vacrel->rel_pages; /* After possible rel truncation */
- visibilitymap_count(rel, &new_rel_allvisible, NULL);
+ visibilitymap_count(rel, &new_rel_allvisible, &new_rel_allfrozen);
if (new_rel_allvisible > new_rel_pages)
new_rel_allvisible = new_rel_pages;
+ /*
+ * An all-frozen block _must_ be all-visible. As such, clamp the count of
+ * all-frozen blocks to the count of all-visible blocks.
+ */
+ if (new_rel_allfrozen > new_rel_allvisible)
+ new_rel_allfrozen = new_rel_allvisible;
+
/*
* Now actually update rel's pg_class entry.
*
@@ -570,7 +578,8 @@ heap_vacuum_rel(Relation rel, VacuumParams *params,
* scan every page that isn't skipped using the visibility map.
*/
vac_update_relstats(rel, new_rel_pages, vacrel->new_live_tuples,
- new_rel_allvisible, vacrel->nindexes > 0,
+ new_rel_allvisible, new_rel_allfrozen,
+ vacrel->nindexes > 0,
vacrel->NewRelfrozenXid, vacrel->NewRelminMxid,
&frozenxid_updated, &minmulti_updated, false);
@@ -3100,7 +3109,7 @@ update_relstats_all_indexes(LVRelState *vacrel)
vac_update_relstats(indrel,
istat->num_pages,
istat->num_index_tuples,
- 0,
+ 0, 0,
false,
InvalidTransactionId,
InvalidMultiXactId,
diff --git a/src/backend/catalog/heap.c b/src/backend/catalog/heap.c
index 0078a12f26e..d150d2b9a72 100644
--- a/src/backend/catalog/heap.c
+++ b/src/backend/catalog/heap.c
@@ -920,6 +920,7 @@ InsertPgClassTuple(Relation pg_class_desc,
values[Anum_pg_class_relpages - 1] = Int32GetDatum(rd_rel->relpages);
values[Anum_pg_class_reltuples - 1] = Float4GetDatum(rd_rel->reltuples);
values[Anum_pg_class_relallvisible - 1] = Int32GetDatum(rd_rel->relallvisible);
+ values[Anum_pg_class_relallfrozen - 1] = Int32GetDatum(rd_rel->relallfrozen);
values[Anum_pg_class_reltoastrelid - 1] = ObjectIdGetDatum(rd_rel->reltoastrelid);
values[Anum_pg_class_relhasindex - 1] = BoolGetDatum(rd_rel->relhasindex);
values[Anum_pg_class_relisshared - 1] = BoolGetDatum(rd_rel->relisshared);
@@ -990,6 +991,7 @@ AddNewRelationTuple(Relation pg_class_desc,
new_rel_reltup->relpages = 0;
new_rel_reltup->reltuples = -1;
new_rel_reltup->relallvisible = 0;
+ new_rel_reltup->relallfrozen = 0;
/* Sequences always have a known size */
if (relkind == RELKIND_SEQUENCE)
diff --git a/src/backend/catalog/index.c b/src/backend/catalog/index.c
index 9162b9f81a2..6f1bc159ecd 100644
--- a/src/backend/catalog/index.c
+++ b/src/backend/catalog/index.c
@@ -2795,8 +2795,8 @@ FormIndexDatum(IndexInfo *indexInfo,
* hasindex: set relhasindex to this value
* reltuples: if >= 0, set reltuples to this value; else no change
*
- * If reltuples >= 0, relpages and relallvisible are also updated (using
- * RelationGetNumberOfBlocks() and visibilitymap_count()).
+ * If reltuples >= 0, relpages, relallvisible, and relallfrozen are also
+ * updated (using RelationGetNumberOfBlocks() and visibilitymap_count()).
*
* NOTE: an important side-effect of this operation is that an SI invalidation
* message is sent out to all backends --- including me --- causing relcache
@@ -2841,8 +2841,8 @@ index_update_stats(Relation rel,
* transaction could still fail before committing. Setting relhasindex
* true is safe even if there are no indexes (VACUUM will eventually fix
* it). And of course the new relpages and reltuples counts are correct
- * regardless. However, we don't want to change relpages (or
- * relallvisible) if the caller isn't providing an updated reltuples
+ * regardless. However, we don't want to change relpages (or relallvisible
+ * and relallfrozen) if the caller isn't providing an updated reltuples
* count, because that would bollix the reltuples/relpages ratio which is
* what's really important.
*/
@@ -2888,12 +2888,18 @@ index_update_stats(Relation rel,
if (reltuples >= 0 && !IsBinaryUpgrade)
{
BlockNumber relpages = RelationGetNumberOfBlocks(rel);
- BlockNumber relallvisible;
+ BlockNumber relallvisible = 0;
+ BlockNumber relallfrozen = 0;
+ /* don't bother for indexes */
if (rd_rel->relkind != RELKIND_INDEX)
- visibilitymap_count(rel, &relallvisible, NULL);
- else /* don't bother for indexes */
- relallvisible = 0;
+ {
+ visibilitymap_count(rel, &relallvisible, &relallfrozen);
+
+ /* Every all-frozen page must also be set all-visible in the VM */
+ if (relallfrozen > relallvisible)
+ relallfrozen = relallvisible;
+ }
if (rd_rel->relpages != (int32) relpages)
{
@@ -2910,6 +2916,11 @@ index_update_stats(Relation rel,
rd_rel->relallvisible = (int32) relallvisible;
dirty = true;
}
+ if (rd_rel->relallfrozen != (int32) relallfrozen)
+ {
+ rd_rel->relallfrozen = (int32) relallfrozen;
+ dirty = true;
+ }
}
/*
diff --git a/src/backend/commands/analyze.c b/src/backend/commands/analyze.c
index 38fb4c3ef23..0928592272e 100644
--- a/src/backend/commands/analyze.c
+++ b/src/backend/commands/analyze.c
@@ -630,12 +630,11 @@ do_analyze_rel(Relation onerel, VacuumParams *params,
*/
if (!inh)
{
- BlockNumber relallvisible;
+ BlockNumber relallvisible = 0;
+ BlockNumber relallfrozen = 0;
if (RELKIND_HAS_STORAGE(onerel->rd_rel->relkind))
- visibilitymap_count(onerel, &relallvisible, NULL);
- else
- relallvisible = 0;
+ visibilitymap_count(onerel, &relallvisible, &relallfrozen);
/*
* Update pg_class for table relation. CCI first, in case acquirefunc
@@ -646,6 +645,7 @@ do_analyze_rel(Relation onerel, VacuumParams *params,
relpages,
totalrows,
relallvisible,
+ relallfrozen,
hasindex,
InvalidTransactionId,
InvalidMultiXactId,
@@ -662,7 +662,7 @@ do_analyze_rel(Relation onerel, VacuumParams *params,
vac_update_relstats(Irel[ind],
RelationGetNumberOfBlocks(Irel[ind]),
totalindexrows,
- 0,
+ 0, 0,
false,
InvalidTransactionId,
InvalidMultiXactId,
@@ -678,7 +678,7 @@ do_analyze_rel(Relation onerel, VacuumParams *params,
*/
CommandCounterIncrement();
vac_update_relstats(onerel, -1, totalrows,
- 0, hasindex, InvalidTransactionId,
+ 0, 0, hasindex, InvalidTransactionId,
InvalidMultiXactId,
NULL, NULL,
in_outer_xact);
diff --git a/src/backend/commands/cluster.c b/src/backend/commands/cluster.c
index 78f96789b0e..43763550668 100644
--- a/src/backend/commands/cluster.c
+++ b/src/backend/commands/cluster.c
@@ -1224,6 +1224,7 @@ swap_relation_files(Oid r1, Oid r2, bool target_is_pg_class,
int32 swap_pages;
float4 swap_tuples;
int32 swap_allvisible;
+ int32 swap_allfrozen;
swap_pages = relform1->relpages;
relform1->relpages = relform2->relpages;
@@ -1236,6 +1237,10 @@ swap_relation_files(Oid r1, Oid r2, bool target_is_pg_class,
swap_allvisible = relform1->relallvisible;
relform1->relallvisible = relform2->relallvisible;
relform2->relallvisible = swap_allvisible;
+
+ swap_allfrozen = relform1->relallfrozen;
+ relform1->relallfrozen = relform2->relallfrozen;
+ relform2->relallfrozen = swap_allfrozen;
}
/*
diff --git a/src/backend/commands/vacuum.c b/src/backend/commands/vacuum.c
index ac8f5d9c259..7ed4df509c5 100644
--- a/src/backend/commands/vacuum.c
+++ b/src/backend/commands/vacuum.c
@@ -1410,6 +1410,7 @@ void
vac_update_relstats(Relation relation,
BlockNumber num_pages, double num_tuples,
BlockNumber num_all_visible_pages,
+ BlockNumber num_all_frozen_pages,
bool hasindex, TransactionId frozenxid,
MultiXactId minmulti,
bool *frozenxid_updated, bool *minmulti_updated,
@@ -1459,6 +1460,11 @@ vac_update_relstats(Relation relation,
pgcform->relallvisible = (int32) num_all_visible_pages;
dirty = true;
}
+ if (pgcform->relallfrozen != (int32) num_all_frozen_pages)
+ {
+ pgcform->relallfrozen = (int32) num_all_frozen_pages;
+ dirty = true;
+ }
/* Apply DDL updates, but not inside an outer transaction (see above) */
diff --git a/src/backend/statistics/relation_stats.c b/src/backend/statistics/relation_stats.c
index 5a2aabc921e..69892f19978 100644
--- a/src/backend/statistics/relation_stats.c
+++ b/src/backend/statistics/relation_stats.c
@@ -54,6 +54,10 @@ static bool relation_statistics_update(FunctionCallInfo fcinfo, int elevel);
/*
* Internal function for modifying statistics for a relation.
+ *
+ * Up to four pg_class columns may be updated even though only three relation
+ * statistics may be modified; relallfrozen is always set to -1 when
+ * relallvisible is updated manually.
*/
static bool
relation_statistics_update(FunctionCallInfo fcinfo, int elevel)
@@ -62,9 +66,9 @@ relation_statistics_update(FunctionCallInfo fcinfo, int elevel)
Relation crel;
HeapTuple ctup;
Form_pg_class pgcform;
- int replaces[3] = {0};
- Datum values[3] = {0};
- bool nulls[3] = {0};
+ int replaces[4] = {0};
+ Datum values[4] = {0};
+ bool nulls[4] = {0};
int ncols = 0;
TupleDesc tupdesc;
bool result = true;
@@ -154,6 +158,16 @@ relation_statistics_update(FunctionCallInfo fcinfo, int elevel)
replaces[ncols] = Anum_pg_class_relallvisible;
values[ncols] = Int32GetDatum(relallvisible);
ncols++;
+
+ /*
+ * If we are modifying relallvisible manually, it is not clear
+ * what relallfrozen value would make sense. Therefore, set it to
+ * -1, or unknown. It will be updated the next time these fields
+ * are updated.
+ */
+ replaces[ncols] = Anum_pg_class_relallfrozen;
+ values[ncols] = Int32GetDatum(-1);
+ ncols++;
}
}
diff --git a/src/backend/utils/cache/relcache.c b/src/backend/utils/cache/relcache.c
index c326f687eb4..4bd9e10310c 100644
--- a/src/backend/utils/cache/relcache.c
+++ b/src/backend/utils/cache/relcache.c
@@ -1936,6 +1936,7 @@ formrdesc(const char *relationName, Oid relationReltype,
relation->rd_rel->relpages = 0;
relation->rd_rel->reltuples = -1;
relation->rd_rel->relallvisible = 0;
+ relation->rd_rel->relallfrozen = 0;
relation->rd_rel->relkind = RELKIND_RELATION;
relation->rd_rel->relnatts = (int16) natts;
relation->rd_rel->relam = HEAP_TABLE_AM_OID;
@@ -3931,6 +3932,7 @@ RelationSetNewRelfilenumber(Relation relation, char persistence)
classform->relpages = 0; /* it's empty until further notice */
classform->reltuples = -1;
classform->relallvisible = 0;
+ classform->relallfrozen = 0;
}
classform->relfrozenxid = freezeXid;
classform->relminmxid = minmulti;
diff --git a/src/include/catalog/catversion.h b/src/include/catalog/catversion.h
index fc1c125d0d0..21dfcb16d27 100644
--- a/src/include/catalog/catversion.h
+++ b/src/include/catalog/catversion.h
@@ -57,6 +57,6 @@
*/
/* yyyymmddN */
-#define CATALOG_VERSION_NO 202410242
+#define CATALOG_VERSION_NO 202410251
#endif
diff --git a/src/include/catalog/pg_class.h b/src/include/catalog/pg_class.h
index 0fc2c093b0d..b915bef9aa5 100644
--- a/src/include/catalog/pg_class.h
+++ b/src/include/catalog/pg_class.h
@@ -68,6 +68,9 @@ CATALOG(pg_class,1259,RelationRelationId) BKI_BOOTSTRAP BKI_ROWTYPE_OID(83,Relat
/* # of all-visible blocks (not always up-to-date) */
int32 relallvisible BKI_DEFAULT(0);
+ /* # of all-frozen blocks (not always up-to-date; -1 means "unknown") */
+ int32 relallfrozen BKI_DEFAULT(0);
+
/* OID of toast table; 0 if none */
Oid reltoastrelid BKI_DEFAULT(0) BKI_LOOKUP_OPT(pg_class);
diff --git a/src/include/commands/vacuum.h b/src/include/commands/vacuum.h
index 759f9a87d38..c3fd2919e64 100644
--- a/src/include/commands/vacuum.h
+++ b/src/include/commands/vacuum.h
@@ -329,6 +329,7 @@ extern void vac_update_relstats(Relation relation,
BlockNumber num_pages,
double num_tuples,
BlockNumber num_all_visible_pages,
+ BlockNumber num_all_frozen_pages,
bool hasindex,
TransactionId frozenxid,
MultiXactId minmulti,
--
2.34.1
On Fri, Oct 25, 2024 at 11:14 AM Melanie Plageman
<melanieplageman@gmail.com> wrote:
I've done something similar to this in attached v2.
This needed a rebase. See attached v4.
- Melanie
Attachments:
v4-0001-Add-relallfrozen-to-pg_class.patchapplication/octet-stream; name=v4-0001-Add-relallfrozen-to-pg_class.patchDownload
From 2ed8278b4fb44050c4081b021bf59bcc33fd107e Mon Sep 17 00:00:00 2001
From: Melanie Plageman <melanieplageman@gmail.com>
Date: Thu, 16 Jan 2025 16:19:57 -0500
Subject: [PATCH v4 1/2] Add relallfrozen to pg_class
Add relallfrozen, an estimate of the number of pages marked all-frozen
in the visibility map.
pg_class already has relallvisible, an estimate of the number of pages
in the relation marked all-visible in the visibility map. This is used
primarily for planning.
relallfrozen, however, is useful for estimating the outstanding number
of all-visible but not all-frozen pages in the relation for the purposes
of scheduling manual VACUUMs and tuning vacuum freeze parameters.
In the future, this field could be used to trigger more frequent vacuums
on insert-focused workloads with significant volume of frozen data.
Reviewed-by: Greg Sabino Mullane
---
doc/src/sgml/catalogs.sgml | 20 ++++++++++++++++++++
src/backend/access/heap/vacuumlazy.c | 17 +++++++++++++----
src/backend/catalog/heap.c | 2 ++
src/backend/catalog/index.c | 22 +++++++++++++++++-----
src/backend/commands/analyze.c | 12 ++++++------
src/backend/commands/cluster.c | 5 +++++
src/backend/commands/vacuum.c | 15 ++++++++++++++-
src/backend/statistics/relation_stats.c | 23 ++++++++++++++++++++---
src/backend/utils/cache/relcache.c | 2 ++
src/include/catalog/pg_class.h | 8 ++++++++
src/include/commands/vacuum.h | 1 +
11 files changed, 108 insertions(+), 19 deletions(-)
diff --git a/doc/src/sgml/catalogs.sgml b/doc/src/sgml/catalogs.sgml
index d3036c5ba9d..d218d3702e9 100644
--- a/doc/src/sgml/catalogs.sgml
+++ b/doc/src/sgml/catalogs.sgml
@@ -2064,6 +2064,26 @@ SCRAM-SHA-256$<replaceable><iteration count></replaceable>:<replaceable>&l
</para></entry>
</row>
+ <row>
+ <entry role="catalog_table_entry"><para role="column_definition">
+ <structfield>relallfrozen</structfield> <type>int4</type>
+ </para>
+ <para>
+ Number of pages that are marked all-frozen in the table's visibility
+ map. This is only an estimate used for triggering autovacuums. It is
+ updated by <link linkend="sql-vacuum"><command>VACUUM</command></link>,
+ <link linkend="sql-analyze"><command>ANALYZE</command></link>,
+ and a few DDL commands such as
+ <link linkend="sql-createindex"><command>CREATE INDEX</command></link>.
+ <structfield>relallfrozen</structfield> must be less than or equal to
+ <strutfield>relallvisible</structfield> as an all-frozen page must be
+ all-visible. If <structfield>relallvisible</structfield> was updated
+ manually, <structfield>relallfrozen</structfield> will be -1 until the
+ next time they are updated.
+ </para></entry>
+ </row>
+
+
<row>
<entry role="catalog_table_entry"><para role="column_definition">
<structfield>reltoastrelid</structfield> <type>oid</type>
diff --git a/src/backend/access/heap/vacuumlazy.c b/src/backend/access/heap/vacuumlazy.c
index 5b0e790e121..ec73471c2c4 100644
--- a/src/backend/access/heap/vacuumlazy.c
+++ b/src/backend/access/heap/vacuumlazy.c
@@ -370,7 +370,8 @@ heap_vacuum_rel(Relation rel, VacuumParams *params,
minmulti_updated;
BlockNumber orig_rel_pages,
new_rel_pages,
- new_rel_allvisible;
+ new_rel_allvisible,
+ new_rel_allfrozen;
PGRUsage ru0;
TimestampTz starttime = 0;
PgStat_Counter startreadtime = 0,
@@ -629,10 +630,17 @@ heap_vacuum_rel(Relation rel, VacuumParams *params,
* pg_class.relpages to
*/
new_rel_pages = vacrel->rel_pages; /* After possible rel truncation */
- visibilitymap_count(rel, &new_rel_allvisible, NULL);
+ visibilitymap_count(rel, &new_rel_allvisible, &new_rel_allfrozen);
if (new_rel_allvisible > new_rel_pages)
new_rel_allvisible = new_rel_pages;
+ /*
+ * An all-frozen block _must_ be all-visible. As such, clamp the count of
+ * all-frozen blocks to the count of all-visible blocks.
+ */
+ if (new_rel_allfrozen > new_rel_allvisible)
+ new_rel_allfrozen = new_rel_allvisible;
+
/*
* Now actually update rel's pg_class entry.
*
@@ -641,7 +649,8 @@ heap_vacuum_rel(Relation rel, VacuumParams *params,
* scan every page that isn't skipped using the visibility map.
*/
vac_update_relstats(rel, new_rel_pages, vacrel->new_live_tuples,
- new_rel_allvisible, vacrel->nindexes > 0,
+ new_rel_allvisible, new_rel_allfrozen,
+ vacrel->nindexes > 0,
vacrel->NewRelfrozenXid, vacrel->NewRelminMxid,
&frozenxid_updated, &minmulti_updated, false);
@@ -3248,7 +3257,7 @@ update_relstats_all_indexes(LVRelState *vacrel)
vac_update_relstats(indrel,
istat->num_pages,
istat->num_index_tuples,
- 0,
+ 0, 0,
false,
InvalidTransactionId,
InvalidMultiXactId,
diff --git a/src/backend/catalog/heap.c b/src/backend/catalog/heap.c
index 57ef466acce..5ab75d5c977 100644
--- a/src/backend/catalog/heap.c
+++ b/src/backend/catalog/heap.c
@@ -913,6 +913,7 @@ InsertPgClassTuple(Relation pg_class_desc,
values[Anum_pg_class_relpages - 1] = Int32GetDatum(rd_rel->relpages);
values[Anum_pg_class_reltuples - 1] = Float4GetDatum(rd_rel->reltuples);
values[Anum_pg_class_relallvisible - 1] = Int32GetDatum(rd_rel->relallvisible);
+ values[Anum_pg_class_relallfrozen - 1] = Int32GetDatum(rd_rel->relallfrozen);
values[Anum_pg_class_reltoastrelid - 1] = ObjectIdGetDatum(rd_rel->reltoastrelid);
values[Anum_pg_class_relhasindex - 1] = BoolGetDatum(rd_rel->relhasindex);
values[Anum_pg_class_relisshared - 1] = BoolGetDatum(rd_rel->relisshared);
@@ -983,6 +984,7 @@ AddNewRelationTuple(Relation pg_class_desc,
new_rel_reltup->relpages = 0;
new_rel_reltup->reltuples = -1;
new_rel_reltup->relallvisible = 0;
+ new_rel_reltup->relallfrozen = 0;
/* Sequences always have a known size */
if (relkind == RELKIND_SEQUENCE)
diff --git a/src/backend/catalog/index.c b/src/backend/catalog/index.c
index 7377912b41e..ee72a1e5e41 100644
--- a/src/backend/catalog/index.c
+++ b/src/backend/catalog/index.c
@@ -2792,8 +2792,8 @@ FormIndexDatum(IndexInfo *indexInfo,
* hasindex: set relhasindex to this value
* reltuples: if >= 0, set reltuples to this value; else no change
*
- * If reltuples >= 0, relpages and relallvisible are also updated (using
- * RelationGetNumberOfBlocks() and visibilitymap_count()).
+ * If reltuples >= 0, relpages, relallvisible, and relallfrozen are also
+ * updated (using RelationGetNumberOfBlocks() and visibilitymap_count()).
*
* NOTE: an important side-effect of this operation is that an SI invalidation
* message is sent out to all backends --- including me --- causing relcache
@@ -2811,6 +2811,7 @@ index_update_stats(Relation rel,
bool update_stats;
BlockNumber relpages = 0; /* keep compiler quiet */
BlockNumber relallvisible = 0;
+ BlockNumber relallfrozen = 0;
Oid relid = RelationGetRelid(rel);
Relation pg_class;
ScanKeyData key[1];
@@ -2850,7 +2851,13 @@ index_update_stats(Relation rel,
relpages = RelationGetNumberOfBlocks(rel);
if (rel->rd_rel->relkind != RELKIND_INDEX)
- visibilitymap_count(rel, &relallvisible, NULL);
+ {
+ visibilitymap_count(rel, &relallvisible, &relallfrozen);
+
+ /* An all-frozen block must be all-visible in the VM */
+ if (relallfrozen > relallvisible)
+ relallfrozen = relallvisible;
+ }
}
/*
@@ -2875,8 +2882,8 @@ index_update_stats(Relation rel,
* transaction could still fail before committing. Setting relhasindex
* true is safe even if there are no indexes (VACUUM will eventually fix
* it). And of course the new relpages and reltuples counts are correct
- * regardless. However, we don't want to change relpages (or
- * relallvisible) if the caller isn't providing an updated reltuples
+ * regardless. However, we don't want to change relpages (or relallvisible
+ * and relallfrozen) if the caller isn't providing an updated reltuples
* count, because that would bollix the reltuples/relpages ratio which is
* what's really important.
*/
@@ -2923,6 +2930,11 @@ index_update_stats(Relation rel,
rd_rel->relallvisible = (int32) relallvisible;
dirty = true;
}
+ if (rd_rel->relallfrozen != (int32) relallfrozen)
+ {
+ rd_rel->relallfrozen = (int32) relallfrozen;
+ dirty = true;
+ }
}
/*
diff --git a/src/backend/commands/analyze.c b/src/backend/commands/analyze.c
index 2a7769b1fd1..927b35ead34 100644
--- a/src/backend/commands/analyze.c
+++ b/src/backend/commands/analyze.c
@@ -628,12 +628,11 @@ do_analyze_rel(Relation onerel, VacuumParams *params,
*/
if (!inh)
{
- BlockNumber relallvisible;
+ BlockNumber relallvisible = 0;
+ BlockNumber relallfrozen = 0;
if (RELKIND_HAS_STORAGE(onerel->rd_rel->relkind))
- visibilitymap_count(onerel, &relallvisible, NULL);
- else
- relallvisible = 0;
+ visibilitymap_count(onerel, &relallvisible, &relallfrozen);
/*
* Update pg_class for table relation. CCI first, in case acquirefunc
@@ -644,6 +643,7 @@ do_analyze_rel(Relation onerel, VacuumParams *params,
relpages,
totalrows,
relallvisible,
+ relallfrozen,
hasindex,
InvalidTransactionId,
InvalidMultiXactId,
@@ -660,7 +660,7 @@ do_analyze_rel(Relation onerel, VacuumParams *params,
vac_update_relstats(Irel[ind],
RelationGetNumberOfBlocks(Irel[ind]),
totalindexrows,
- 0,
+ 0, 0,
false,
InvalidTransactionId,
InvalidMultiXactId,
@@ -676,7 +676,7 @@ do_analyze_rel(Relation onerel, VacuumParams *params,
*/
CommandCounterIncrement();
vac_update_relstats(onerel, -1, totalrows,
- 0, hasindex, InvalidTransactionId,
+ 0, 0, hasindex, InvalidTransactionId,
InvalidMultiXactId,
NULL, NULL,
in_outer_xact);
diff --git a/src/backend/commands/cluster.c b/src/backend/commands/cluster.c
index 99193f5c886..54a08e4102e 100644
--- a/src/backend/commands/cluster.c
+++ b/src/backend/commands/cluster.c
@@ -1226,6 +1226,7 @@ swap_relation_files(Oid r1, Oid r2, bool target_is_pg_class,
int32 swap_pages;
float4 swap_tuples;
int32 swap_allvisible;
+ int32 swap_allfrozen;
swap_pages = relform1->relpages;
relform1->relpages = relform2->relpages;
@@ -1238,6 +1239,10 @@ swap_relation_files(Oid r1, Oid r2, bool target_is_pg_class,
swap_allvisible = relform1->relallvisible;
relform1->relallvisible = relform2->relallvisible;
relform2->relallvisible = swap_allvisible;
+
+ swap_allfrozen = relform1->relallfrozen;
+ relform1->relallfrozen = relform2->relallfrozen;
+ relform2->relallfrozen = swap_allfrozen;
}
/*
diff --git a/src/backend/commands/vacuum.c b/src/backend/commands/vacuum.c
index e6745e6145c..376ce2e489a 100644
--- a/src/backend/commands/vacuum.c
+++ b/src/backend/commands/vacuum.c
@@ -1410,6 +1410,7 @@ void
vac_update_relstats(Relation relation,
BlockNumber num_pages, double num_tuples,
BlockNumber num_all_visible_pages,
+ BlockNumber num_all_frozen_pages,
bool hasindex, TransactionId frozenxid,
MultiXactId minmulti,
bool *frozenxid_updated, bool *minmulti_updated,
@@ -1441,8 +1442,15 @@ vac_update_relstats(Relation relation,
relid);
pgcform = (Form_pg_class) GETSTRUCT(ctup);
- /* Apply statistical updates, if any, to copied tuple */
+ /*
+ * An all-frozen block must be marked all-visible in the VM. While callers
+ * are likely to check this themselves, it is worth ensuring we don't put
+ * incorrect information in pg_class.
+ */
+ if (num_all_frozen_pages > num_all_visible_pages)
+ num_all_frozen_pages = num_all_visible_pages;
+ /* Apply statistical updates, if any, to copied tuple */
dirty = false;
if (pgcform->relpages != (int32) num_pages)
{
@@ -1459,6 +1467,11 @@ vac_update_relstats(Relation relation,
pgcform->relallvisible = (int32) num_all_visible_pages;
dirty = true;
}
+ if (pgcform->relallfrozen != (int32) num_all_frozen_pages)
+ {
+ pgcform->relallfrozen = (int32) num_all_frozen_pages;
+ dirty = true;
+ }
/* Apply DDL updates, but not inside an outer transaction (see above) */
diff --git a/src/backend/statistics/relation_stats.c b/src/backend/statistics/relation_stats.c
index 046661d7c3f..758a56f8a46 100644
--- a/src/backend/statistics/relation_stats.c
+++ b/src/backend/statistics/relation_stats.c
@@ -56,6 +56,10 @@ static bool relation_statistics_update(FunctionCallInfo fcinfo, int elevel,
/*
* Internal function for modifying statistics for a relation.
+ *
+ * Up to four pg_class columns may be updated even though only three relation
+ * statistics may be modified; relallfrozen is always set to -1 when
+ * relallvisible is updated manually.
*/
static bool
relation_statistics_update(FunctionCallInfo fcinfo, int elevel, bool inplace)
@@ -167,6 +171,14 @@ relation_statistics_update(FunctionCallInfo fcinfo, int elevel, bool inplace)
if (update_relallvisible && pgcform->relallvisible != relallvisible)
{
pgcform->relallvisible = relallvisible;
+
+ /*
+ * If we are modifying relallvisible manually, it is not clear
+ * what relallfrozen value would make sense. Therefore, set it to
+ * -1 ("unknown"). It will be updated the next time these fields
+ * are updated.
+ */
+ pgcform->relallfrozen = -1;
dirty = true;
}
@@ -182,9 +194,9 @@ relation_statistics_update(FunctionCallInfo fcinfo, int elevel, bool inplace)
TupleDesc tupdesc = RelationGetDescr(crel);
HeapTuple ctup;
Form_pg_class pgcform;
- int replaces[3] = {0};
- Datum values[3] = {0};
- bool nulls[3] = {0};
+ int replaces[4] = {0};
+ Datum values[4] = {0};
+ bool nulls[4] = {0};
int nreplaces = 0;
ctup = SearchSysCache1(RELOID, ObjectIdGetDatum(reloid));
@@ -217,6 +229,11 @@ relation_statistics_update(FunctionCallInfo fcinfo, int elevel, bool inplace)
replaces[nreplaces] = Anum_pg_class_relallvisible;
values[nreplaces] = Int32GetDatum(relallvisible);
nreplaces++;
+
+ /* See comment above in-place update of relallfrozen */
+ replaces[nreplaces] = Anum_pg_class_relallfrozen;
+ values[nreplaces] = Int32GetDatum(-1);
+ nreplaces++;
}
if (nreplaces > 0)
diff --git a/src/backend/utils/cache/relcache.c b/src/backend/utils/cache/relcache.c
index 43219a9629c..efd6bcb3860 100644
--- a/src/backend/utils/cache/relcache.c
+++ b/src/backend/utils/cache/relcache.c
@@ -1925,6 +1925,7 @@ formrdesc(const char *relationName, Oid relationReltype,
relation->rd_rel->relpages = 0;
relation->rd_rel->reltuples = -1;
relation->rd_rel->relallvisible = 0;
+ relation->rd_rel->relallfrozen = 0;
relation->rd_rel->relkind = RELKIND_RELATION;
relation->rd_rel->relnatts = (int16) natts;
@@ -3882,6 +3883,7 @@ RelationSetNewRelfilenumber(Relation relation, char persistence)
classform->relpages = 0; /* it's empty until further notice */
classform->reltuples = -1;
classform->relallvisible = 0;
+ classform->relallfrozen = 0;
}
classform->relfrozenxid = freezeXid;
classform->relminmxid = minmulti;
diff --git a/src/include/catalog/pg_class.h b/src/include/catalog/pg_class.h
index f0d612ca487..fbf42b0e195 100644
--- a/src/include/catalog/pg_class.h
+++ b/src/include/catalog/pg_class.h
@@ -68,6 +68,14 @@ CATALOG(pg_class,1259,RelationRelationId) BKI_BOOTSTRAP BKI_ROWTYPE_OID(83,Relat
/* # of all-visible blocks (not always up-to-date) */
int32 relallvisible BKI_DEFAULT(0);
+ /*
+ * # of all-frozen blocks (not always up-to-date)
+ * Starts as 0 (if it has never been updated).
+ * If relallvisible is manually updated, relallfrozen will be
+ * -1, meaning "unknown"
+ */
+ int32 relallfrozen BKI_DEFAULT(0);
+
/* OID of toast table; 0 if none */
Oid reltoastrelid BKI_DEFAULT(0) BKI_LOOKUP_OPT(pg_class);
diff --git a/src/include/commands/vacuum.h b/src/include/commands/vacuum.h
index 12d0b61950d..b2a678df09e 100644
--- a/src/include/commands/vacuum.h
+++ b/src/include/commands/vacuum.h
@@ -329,6 +329,7 @@ extern void vac_update_relstats(Relation relation,
BlockNumber num_pages,
double num_tuples,
BlockNumber num_all_visible_pages,
+ BlockNumber num_all_frozen_pages,
bool hasindex,
TransactionId frozenxid,
MultiXactId minmulti,
--
2.45.2
v4-0002-Trigger-more-frequent-autovacuums-with-relallfroz.patchapplication/octet-stream; name=v4-0002-Trigger-more-frequent-autovacuums-with-relallfroz.patchDownload
From 3a3ca54a118879d13c18fc2b266ee88edcc338a8 Mon Sep 17 00:00:00 2001
From: Melanie Plageman <melanieplageman@gmail.com>
Date: Thu, 16 Jan 2025 16:31:55 -0500
Subject: [PATCH v4 2/2] Trigger more frequent autovacuums with relallfrozen
Calculate the insert threshold for triggering an autovacuum of a
relation based on the number of unfrozen pages. By only considering the
"active" (unfrozen) portion of the table when calculating how many
tuples to add to the insert threshold, we can trigger more frequent
vacuums of insert-heavy tables and increase the chances of vacuuming
those pages when they still reside in shared buffers.
Reviewed-by: Greg Sabino Mullane
---
doc/src/sgml/config.sgml | 16 +++++-----
src/backend/postmaster/autovacuum.c | 32 +++++++++++++++++--
src/backend/utils/misc/postgresql.conf.sample | 4 +--
3 files changed, 39 insertions(+), 13 deletions(-)
diff --git a/doc/src/sgml/config.sgml b/doc/src/sgml/config.sgml
index a8866292d46..84f2b44ec97 100644
--- a/doc/src/sgml/config.sgml
+++ b/doc/src/sgml/config.sgml
@@ -8651,14 +8651,14 @@ COPY postgres_log FROM '/full/path/to/logfile.csv' WITH csv;
</term>
<listitem>
<para>
- Specifies a fraction of the table size to add to
- <varname>autovacuum_vacuum_insert_threshold</varname>
- when deciding whether to trigger a <command>VACUUM</command>.
- The default is <literal>0.2</literal> (20% of table size).
- This parameter can only be set in the <filename>postgresql.conf</filename>
- file or on the server command line;
- but the setting can be overridden for individual tables by
- changing table storage parameters.
+ Specifies a fraction of the active (unfrozen) table size to add to
+ <varname>autovacuum_vacuum_insert_threshold</varname>
+ when deciding whether to trigger a <command>VACUUM</command>.
+ The default is 0.2 (20% of active table size).
+ This parameter can only be set in the <filename>postgresql.conf</filename>
+ file or on the server command line;
+ but the setting can be overridden for individual tables by
+ changing table storage parameters.
</para>
</listitem>
</varlistentry>
diff --git a/src/backend/postmaster/autovacuum.c b/src/backend/postmaster/autovacuum.c
index 0ab921a169b..2d4a7778561 100644
--- a/src/backend/postmaster/autovacuum.c
+++ b/src/backend/postmaster/autovacuum.c
@@ -2929,7 +2929,6 @@ relation_needs_vacanalyze(Oid relid,
{
bool force_vacuum;
bool av_enabled;
- float4 reltuples; /* pg_class.reltuples */
/* constants from reloptions or GUC variables */
int vac_base_thresh,
@@ -3037,7 +3036,12 @@ relation_needs_vacanalyze(Oid relid,
*/
if (PointerIsValid(tabentry) && AutoVacuumingActive())
{
- reltuples = classForm->reltuples;
+ float4 pcnt_unfrozen = 1;
+ float4 reltuples = classForm->reltuples;
+ int32 relpages = classForm->relpages;
+ int32 relallfrozen = classForm->relallfrozen;
+ int32 relallvisible = classForm->relallvisible;
+
vactuples = tabentry->dead_tuples;
instuples = tabentry->ins_since_vacuum;
anltuples = tabentry->mod_since_analyze;
@@ -3046,8 +3050,30 @@ relation_needs_vacanalyze(Oid relid,
if (reltuples < 0)
reltuples = 0;
+ /*
+ * If the table has been vacuumed and we have reliable data for
+ * relallfrozen and relallvisible, calculate the unfrozen percentage
+ * of the table to modify insert scale factor. This helps us decide
+ * whether or not to vacuum an insert-heavy table based on the number
+ * of inserts to the "active" part of the table.
+ *
+ * If relallfrozen is -1, that means relallvisible was updated
+ * manually and we can't rely on relallfrozen.
+ */
+ if (relpages > 0 && reltuples > 0 && relallfrozen > -1)
+ {
+ if (relallvisible > relpages)
+ relallvisible = relpages;
+
+ if (relallfrozen > relallvisible)
+ relallfrozen = relallvisible;
+
+ pcnt_unfrozen = 1 - ((float4) relallfrozen / relpages);
+ }
+
vacthresh = (float4) vac_base_thresh + vac_scale_factor * reltuples;
- vacinsthresh = (float4) vac_ins_base_thresh + vac_ins_scale_factor * reltuples;
+ vacinsthresh = (float4) vac_ins_base_thresh +
+ vac_ins_scale_factor * reltuples * pcnt_unfrozen;
anlthresh = (float4) anl_base_thresh + anl_scale_factor * reltuples;
/*
diff --git a/src/backend/utils/misc/postgresql.conf.sample b/src/backend/utils/misc/postgresql.conf.sample
index 079efa1baa7..1b10f53c659 100644
--- a/src/backend/utils/misc/postgresql.conf.sample
+++ b/src/backend/utils/misc/postgresql.conf.sample
@@ -667,8 +667,8 @@ autovacuum_worker_slots = 16 # autovacuum worker slots to allocate
#autovacuum_analyze_threshold = 50 # min number of row updates before
# analyze
#autovacuum_vacuum_scale_factor = 0.2 # fraction of table size before vacuum
-#autovacuum_vacuum_insert_scale_factor = 0.2 # fraction of inserts over table
- # size before insert vacuum
+#autovacuum_vacuum_insert_scale_factor = 0.2 # fraction of inserts over active
+ # table size before insert vacuum
#autovacuum_analyze_scale_factor = 0.1 # fraction of table size before analyze
#autovacuum_freeze_max_age = 200000000 # maximum XID age before forced vacuum
# (change requires restart)
--
2.45.2
On Thu, Jan 16, 2025 at 4:43 PM Melanie Plageman
<melanieplageman@gmail.com> wrote:
On Fri, Oct 25, 2024 at 11:14 AM Melanie Plageman
<melanieplageman@gmail.com> wrote:I've done something similar to this in attached v2.
This needed a rebase. See attached v4.
Whoops -- docs didn't build. Attached v5.
- Melanie
Attachments:
v5-0002-Trigger-more-frequent-autovacuums-with-relallfroz.patchapplication/octet-stream; name=v5-0002-Trigger-more-frequent-autovacuums-with-relallfroz.patchDownload
From c27e370df14f6f20d21a76c9563d6f00019949e1 Mon Sep 17 00:00:00 2001
From: Melanie Plageman <melanieplageman@gmail.com>
Date: Thu, 16 Jan 2025 16:31:55 -0500
Subject: [PATCH v5 2/2] Trigger more frequent autovacuums with relallfrozen
Calculate the insert threshold for triggering an autovacuum of a
relation based on the number of unfrozen pages. By only considering the
"active" (unfrozen) portion of the table when calculating how many
tuples to add to the insert threshold, we can trigger more frequent
vacuums of insert-heavy tables and increase the chances of vacuuming
those pages when they still reside in shared buffers.
Reviewed-by: Greg Sabino Mullane
---
doc/src/sgml/config.sgml | 16 +++++-----
src/backend/postmaster/autovacuum.c | 32 +++++++++++++++++--
src/backend/utils/misc/postgresql.conf.sample | 4 +--
3 files changed, 39 insertions(+), 13 deletions(-)
diff --git a/doc/src/sgml/config.sgml b/doc/src/sgml/config.sgml
index a8866292d46..84f2b44ec97 100644
--- a/doc/src/sgml/config.sgml
+++ b/doc/src/sgml/config.sgml
@@ -8651,14 +8651,14 @@ COPY postgres_log FROM '/full/path/to/logfile.csv' WITH csv;
</term>
<listitem>
<para>
- Specifies a fraction of the table size to add to
- <varname>autovacuum_vacuum_insert_threshold</varname>
- when deciding whether to trigger a <command>VACUUM</command>.
- The default is <literal>0.2</literal> (20% of table size).
- This parameter can only be set in the <filename>postgresql.conf</filename>
- file or on the server command line;
- but the setting can be overridden for individual tables by
- changing table storage parameters.
+ Specifies a fraction of the active (unfrozen) table size to add to
+ <varname>autovacuum_vacuum_insert_threshold</varname>
+ when deciding whether to trigger a <command>VACUUM</command>.
+ The default is 0.2 (20% of active table size).
+ This parameter can only be set in the <filename>postgresql.conf</filename>
+ file or on the server command line;
+ but the setting can be overridden for individual tables by
+ changing table storage parameters.
</para>
</listitem>
</varlistentry>
diff --git a/src/backend/postmaster/autovacuum.c b/src/backend/postmaster/autovacuum.c
index 0ab921a169b..2d4a7778561 100644
--- a/src/backend/postmaster/autovacuum.c
+++ b/src/backend/postmaster/autovacuum.c
@@ -2929,7 +2929,6 @@ relation_needs_vacanalyze(Oid relid,
{
bool force_vacuum;
bool av_enabled;
- float4 reltuples; /* pg_class.reltuples */
/* constants from reloptions or GUC variables */
int vac_base_thresh,
@@ -3037,7 +3036,12 @@ relation_needs_vacanalyze(Oid relid,
*/
if (PointerIsValid(tabentry) && AutoVacuumingActive())
{
- reltuples = classForm->reltuples;
+ float4 pcnt_unfrozen = 1;
+ float4 reltuples = classForm->reltuples;
+ int32 relpages = classForm->relpages;
+ int32 relallfrozen = classForm->relallfrozen;
+ int32 relallvisible = classForm->relallvisible;
+
vactuples = tabentry->dead_tuples;
instuples = tabentry->ins_since_vacuum;
anltuples = tabentry->mod_since_analyze;
@@ -3046,8 +3050,30 @@ relation_needs_vacanalyze(Oid relid,
if (reltuples < 0)
reltuples = 0;
+ /*
+ * If the table has been vacuumed and we have reliable data for
+ * relallfrozen and relallvisible, calculate the unfrozen percentage
+ * of the table to modify insert scale factor. This helps us decide
+ * whether or not to vacuum an insert-heavy table based on the number
+ * of inserts to the "active" part of the table.
+ *
+ * If relallfrozen is -1, that means relallvisible was updated
+ * manually and we can't rely on relallfrozen.
+ */
+ if (relpages > 0 && reltuples > 0 && relallfrozen > -1)
+ {
+ if (relallvisible > relpages)
+ relallvisible = relpages;
+
+ if (relallfrozen > relallvisible)
+ relallfrozen = relallvisible;
+
+ pcnt_unfrozen = 1 - ((float4) relallfrozen / relpages);
+ }
+
vacthresh = (float4) vac_base_thresh + vac_scale_factor * reltuples;
- vacinsthresh = (float4) vac_ins_base_thresh + vac_ins_scale_factor * reltuples;
+ vacinsthresh = (float4) vac_ins_base_thresh +
+ vac_ins_scale_factor * reltuples * pcnt_unfrozen;
anlthresh = (float4) anl_base_thresh + anl_scale_factor * reltuples;
/*
diff --git a/src/backend/utils/misc/postgresql.conf.sample b/src/backend/utils/misc/postgresql.conf.sample
index 079efa1baa7..1b10f53c659 100644
--- a/src/backend/utils/misc/postgresql.conf.sample
+++ b/src/backend/utils/misc/postgresql.conf.sample
@@ -667,8 +667,8 @@ autovacuum_worker_slots = 16 # autovacuum worker slots to allocate
#autovacuum_analyze_threshold = 50 # min number of row updates before
# analyze
#autovacuum_vacuum_scale_factor = 0.2 # fraction of table size before vacuum
-#autovacuum_vacuum_insert_scale_factor = 0.2 # fraction of inserts over table
- # size before insert vacuum
+#autovacuum_vacuum_insert_scale_factor = 0.2 # fraction of inserts over active
+ # table size before insert vacuum
#autovacuum_analyze_scale_factor = 0.1 # fraction of table size before analyze
#autovacuum_freeze_max_age = 200000000 # maximum XID age before forced vacuum
# (change requires restart)
--
2.45.2
v5-0001-Add-relallfrozen-to-pg_class.patchapplication/octet-stream; name=v5-0001-Add-relallfrozen-to-pg_class.patchDownload
From 61e40cbe7c9df615461174301984552e31006a09 Mon Sep 17 00:00:00 2001
From: Melanie Plageman <melanieplageman@gmail.com>
Date: Thu, 16 Jan 2025 16:19:57 -0500
Subject: [PATCH v5 1/2] Add relallfrozen to pg_class
Add relallfrozen, an estimate of the number of pages marked all-frozen
in the visibility map.
pg_class already has relallvisible, an estimate of the number of pages
in the relation marked all-visible in the visibility map. This is used
primarily for planning.
relallfrozen, however, is useful for estimating the outstanding number
of all-visible but not all-frozen pages in the relation for the purposes
of scheduling manual VACUUMs and tuning vacuum freeze parameters.
In the future, this field could be used to trigger more frequent vacuums
on insert-focused workloads with significant volume of frozen data.
Reviewed-by: Greg Sabino Mullane
---
doc/src/sgml/catalogs.sgml | 20 ++++++++++++++++++++
src/backend/access/heap/vacuumlazy.c | 17 +++++++++++++----
src/backend/catalog/heap.c | 2 ++
src/backend/catalog/index.c | 22 +++++++++++++++++-----
src/backend/commands/analyze.c | 12 ++++++------
src/backend/commands/cluster.c | 5 +++++
src/backend/commands/vacuum.c | 15 ++++++++++++++-
src/backend/statistics/relation_stats.c | 23 ++++++++++++++++++++---
src/backend/utils/cache/relcache.c | 2 ++
src/include/catalog/pg_class.h | 8 ++++++++
src/include/commands/vacuum.h | 1 +
11 files changed, 108 insertions(+), 19 deletions(-)
diff --git a/doc/src/sgml/catalogs.sgml b/doc/src/sgml/catalogs.sgml
index d3036c5ba9d..bc9a735e5a7 100644
--- a/doc/src/sgml/catalogs.sgml
+++ b/doc/src/sgml/catalogs.sgml
@@ -2064,6 +2064,26 @@ SCRAM-SHA-256$<replaceable><iteration count></replaceable>:<replaceable>&l
</para></entry>
</row>
+ <row>
+ <entry role="catalog_table_entry"><para role="column_definition">
+ <structfield>relallfrozen</structfield> <type>int4</type>
+ </para>
+ <para>
+ Number of pages that are marked all-frozen in the table's visibility
+ map. This is only an estimate used for triggering autovacuums. It is
+ updated by <link linkend="sql-vacuum"><command>VACUUM</command></link>,
+ <link linkend="sql-analyze"><command>ANALYZE</command></link>,
+ and a few DDL commands such as
+ <link linkend="sql-createindex"><command>CREATE INDEX</command></link>.
+ <structfield>relallfrozen</structfield> must be less than or equal to
+ <structfield>relallvisible</structfield> as an all-frozen page must be
+ all-visible. If <structfield>relallvisible</structfield> was updated
+ manually, <structfield>relallfrozen</structfield> will be -1 until the
+ next time they are updated.
+ </para></entry>
+ </row>
+
+
<row>
<entry role="catalog_table_entry"><para role="column_definition">
<structfield>reltoastrelid</structfield> <type>oid</type>
diff --git a/src/backend/access/heap/vacuumlazy.c b/src/backend/access/heap/vacuumlazy.c
index 5b0e790e121..ec73471c2c4 100644
--- a/src/backend/access/heap/vacuumlazy.c
+++ b/src/backend/access/heap/vacuumlazy.c
@@ -370,7 +370,8 @@ heap_vacuum_rel(Relation rel, VacuumParams *params,
minmulti_updated;
BlockNumber orig_rel_pages,
new_rel_pages,
- new_rel_allvisible;
+ new_rel_allvisible,
+ new_rel_allfrozen;
PGRUsage ru0;
TimestampTz starttime = 0;
PgStat_Counter startreadtime = 0,
@@ -629,10 +630,17 @@ heap_vacuum_rel(Relation rel, VacuumParams *params,
* pg_class.relpages to
*/
new_rel_pages = vacrel->rel_pages; /* After possible rel truncation */
- visibilitymap_count(rel, &new_rel_allvisible, NULL);
+ visibilitymap_count(rel, &new_rel_allvisible, &new_rel_allfrozen);
if (new_rel_allvisible > new_rel_pages)
new_rel_allvisible = new_rel_pages;
+ /*
+ * An all-frozen block _must_ be all-visible. As such, clamp the count of
+ * all-frozen blocks to the count of all-visible blocks.
+ */
+ if (new_rel_allfrozen > new_rel_allvisible)
+ new_rel_allfrozen = new_rel_allvisible;
+
/*
* Now actually update rel's pg_class entry.
*
@@ -641,7 +649,8 @@ heap_vacuum_rel(Relation rel, VacuumParams *params,
* scan every page that isn't skipped using the visibility map.
*/
vac_update_relstats(rel, new_rel_pages, vacrel->new_live_tuples,
- new_rel_allvisible, vacrel->nindexes > 0,
+ new_rel_allvisible, new_rel_allfrozen,
+ vacrel->nindexes > 0,
vacrel->NewRelfrozenXid, vacrel->NewRelminMxid,
&frozenxid_updated, &minmulti_updated, false);
@@ -3248,7 +3257,7 @@ update_relstats_all_indexes(LVRelState *vacrel)
vac_update_relstats(indrel,
istat->num_pages,
istat->num_index_tuples,
- 0,
+ 0, 0,
false,
InvalidTransactionId,
InvalidMultiXactId,
diff --git a/src/backend/catalog/heap.c b/src/backend/catalog/heap.c
index 57ef466acce..5ab75d5c977 100644
--- a/src/backend/catalog/heap.c
+++ b/src/backend/catalog/heap.c
@@ -913,6 +913,7 @@ InsertPgClassTuple(Relation pg_class_desc,
values[Anum_pg_class_relpages - 1] = Int32GetDatum(rd_rel->relpages);
values[Anum_pg_class_reltuples - 1] = Float4GetDatum(rd_rel->reltuples);
values[Anum_pg_class_relallvisible - 1] = Int32GetDatum(rd_rel->relallvisible);
+ values[Anum_pg_class_relallfrozen - 1] = Int32GetDatum(rd_rel->relallfrozen);
values[Anum_pg_class_reltoastrelid - 1] = ObjectIdGetDatum(rd_rel->reltoastrelid);
values[Anum_pg_class_relhasindex - 1] = BoolGetDatum(rd_rel->relhasindex);
values[Anum_pg_class_relisshared - 1] = BoolGetDatum(rd_rel->relisshared);
@@ -983,6 +984,7 @@ AddNewRelationTuple(Relation pg_class_desc,
new_rel_reltup->relpages = 0;
new_rel_reltup->reltuples = -1;
new_rel_reltup->relallvisible = 0;
+ new_rel_reltup->relallfrozen = 0;
/* Sequences always have a known size */
if (relkind == RELKIND_SEQUENCE)
diff --git a/src/backend/catalog/index.c b/src/backend/catalog/index.c
index 7377912b41e..ee72a1e5e41 100644
--- a/src/backend/catalog/index.c
+++ b/src/backend/catalog/index.c
@@ -2792,8 +2792,8 @@ FormIndexDatum(IndexInfo *indexInfo,
* hasindex: set relhasindex to this value
* reltuples: if >= 0, set reltuples to this value; else no change
*
- * If reltuples >= 0, relpages and relallvisible are also updated (using
- * RelationGetNumberOfBlocks() and visibilitymap_count()).
+ * If reltuples >= 0, relpages, relallvisible, and relallfrozen are also
+ * updated (using RelationGetNumberOfBlocks() and visibilitymap_count()).
*
* NOTE: an important side-effect of this operation is that an SI invalidation
* message is sent out to all backends --- including me --- causing relcache
@@ -2811,6 +2811,7 @@ index_update_stats(Relation rel,
bool update_stats;
BlockNumber relpages = 0; /* keep compiler quiet */
BlockNumber relallvisible = 0;
+ BlockNumber relallfrozen = 0;
Oid relid = RelationGetRelid(rel);
Relation pg_class;
ScanKeyData key[1];
@@ -2850,7 +2851,13 @@ index_update_stats(Relation rel,
relpages = RelationGetNumberOfBlocks(rel);
if (rel->rd_rel->relkind != RELKIND_INDEX)
- visibilitymap_count(rel, &relallvisible, NULL);
+ {
+ visibilitymap_count(rel, &relallvisible, &relallfrozen);
+
+ /* An all-frozen block must be all-visible in the VM */
+ if (relallfrozen > relallvisible)
+ relallfrozen = relallvisible;
+ }
}
/*
@@ -2875,8 +2882,8 @@ index_update_stats(Relation rel,
* transaction could still fail before committing. Setting relhasindex
* true is safe even if there are no indexes (VACUUM will eventually fix
* it). And of course the new relpages and reltuples counts are correct
- * regardless. However, we don't want to change relpages (or
- * relallvisible) if the caller isn't providing an updated reltuples
+ * regardless. However, we don't want to change relpages (or relallvisible
+ * and relallfrozen) if the caller isn't providing an updated reltuples
* count, because that would bollix the reltuples/relpages ratio which is
* what's really important.
*/
@@ -2923,6 +2930,11 @@ index_update_stats(Relation rel,
rd_rel->relallvisible = (int32) relallvisible;
dirty = true;
}
+ if (rd_rel->relallfrozen != (int32) relallfrozen)
+ {
+ rd_rel->relallfrozen = (int32) relallfrozen;
+ dirty = true;
+ }
}
/*
diff --git a/src/backend/commands/analyze.c b/src/backend/commands/analyze.c
index 2a7769b1fd1..927b35ead34 100644
--- a/src/backend/commands/analyze.c
+++ b/src/backend/commands/analyze.c
@@ -628,12 +628,11 @@ do_analyze_rel(Relation onerel, VacuumParams *params,
*/
if (!inh)
{
- BlockNumber relallvisible;
+ BlockNumber relallvisible = 0;
+ BlockNumber relallfrozen = 0;
if (RELKIND_HAS_STORAGE(onerel->rd_rel->relkind))
- visibilitymap_count(onerel, &relallvisible, NULL);
- else
- relallvisible = 0;
+ visibilitymap_count(onerel, &relallvisible, &relallfrozen);
/*
* Update pg_class for table relation. CCI first, in case acquirefunc
@@ -644,6 +643,7 @@ do_analyze_rel(Relation onerel, VacuumParams *params,
relpages,
totalrows,
relallvisible,
+ relallfrozen,
hasindex,
InvalidTransactionId,
InvalidMultiXactId,
@@ -660,7 +660,7 @@ do_analyze_rel(Relation onerel, VacuumParams *params,
vac_update_relstats(Irel[ind],
RelationGetNumberOfBlocks(Irel[ind]),
totalindexrows,
- 0,
+ 0, 0,
false,
InvalidTransactionId,
InvalidMultiXactId,
@@ -676,7 +676,7 @@ do_analyze_rel(Relation onerel, VacuumParams *params,
*/
CommandCounterIncrement();
vac_update_relstats(onerel, -1, totalrows,
- 0, hasindex, InvalidTransactionId,
+ 0, 0, hasindex, InvalidTransactionId,
InvalidMultiXactId,
NULL, NULL,
in_outer_xact);
diff --git a/src/backend/commands/cluster.c b/src/backend/commands/cluster.c
index 99193f5c886..54a08e4102e 100644
--- a/src/backend/commands/cluster.c
+++ b/src/backend/commands/cluster.c
@@ -1226,6 +1226,7 @@ swap_relation_files(Oid r1, Oid r2, bool target_is_pg_class,
int32 swap_pages;
float4 swap_tuples;
int32 swap_allvisible;
+ int32 swap_allfrozen;
swap_pages = relform1->relpages;
relform1->relpages = relform2->relpages;
@@ -1238,6 +1239,10 @@ swap_relation_files(Oid r1, Oid r2, bool target_is_pg_class,
swap_allvisible = relform1->relallvisible;
relform1->relallvisible = relform2->relallvisible;
relform2->relallvisible = swap_allvisible;
+
+ swap_allfrozen = relform1->relallfrozen;
+ relform1->relallfrozen = relform2->relallfrozen;
+ relform2->relallfrozen = swap_allfrozen;
}
/*
diff --git a/src/backend/commands/vacuum.c b/src/backend/commands/vacuum.c
index e6745e6145c..376ce2e489a 100644
--- a/src/backend/commands/vacuum.c
+++ b/src/backend/commands/vacuum.c
@@ -1410,6 +1410,7 @@ void
vac_update_relstats(Relation relation,
BlockNumber num_pages, double num_tuples,
BlockNumber num_all_visible_pages,
+ BlockNumber num_all_frozen_pages,
bool hasindex, TransactionId frozenxid,
MultiXactId minmulti,
bool *frozenxid_updated, bool *minmulti_updated,
@@ -1441,8 +1442,15 @@ vac_update_relstats(Relation relation,
relid);
pgcform = (Form_pg_class) GETSTRUCT(ctup);
- /* Apply statistical updates, if any, to copied tuple */
+ /*
+ * An all-frozen block must be marked all-visible in the VM. While callers
+ * are likely to check this themselves, it is worth ensuring we don't put
+ * incorrect information in pg_class.
+ */
+ if (num_all_frozen_pages > num_all_visible_pages)
+ num_all_frozen_pages = num_all_visible_pages;
+ /* Apply statistical updates, if any, to copied tuple */
dirty = false;
if (pgcform->relpages != (int32) num_pages)
{
@@ -1459,6 +1467,11 @@ vac_update_relstats(Relation relation,
pgcform->relallvisible = (int32) num_all_visible_pages;
dirty = true;
}
+ if (pgcform->relallfrozen != (int32) num_all_frozen_pages)
+ {
+ pgcform->relallfrozen = (int32) num_all_frozen_pages;
+ dirty = true;
+ }
/* Apply DDL updates, but not inside an outer transaction (see above) */
diff --git a/src/backend/statistics/relation_stats.c b/src/backend/statistics/relation_stats.c
index 046661d7c3f..758a56f8a46 100644
--- a/src/backend/statistics/relation_stats.c
+++ b/src/backend/statistics/relation_stats.c
@@ -56,6 +56,10 @@ static bool relation_statistics_update(FunctionCallInfo fcinfo, int elevel,
/*
* Internal function for modifying statistics for a relation.
+ *
+ * Up to four pg_class columns may be updated even though only three relation
+ * statistics may be modified; relallfrozen is always set to -1 when
+ * relallvisible is updated manually.
*/
static bool
relation_statistics_update(FunctionCallInfo fcinfo, int elevel, bool inplace)
@@ -167,6 +171,14 @@ relation_statistics_update(FunctionCallInfo fcinfo, int elevel, bool inplace)
if (update_relallvisible && pgcform->relallvisible != relallvisible)
{
pgcform->relallvisible = relallvisible;
+
+ /*
+ * If we are modifying relallvisible manually, it is not clear
+ * what relallfrozen value would make sense. Therefore, set it to
+ * -1 ("unknown"). It will be updated the next time these fields
+ * are updated.
+ */
+ pgcform->relallfrozen = -1;
dirty = true;
}
@@ -182,9 +194,9 @@ relation_statistics_update(FunctionCallInfo fcinfo, int elevel, bool inplace)
TupleDesc tupdesc = RelationGetDescr(crel);
HeapTuple ctup;
Form_pg_class pgcform;
- int replaces[3] = {0};
- Datum values[3] = {0};
- bool nulls[3] = {0};
+ int replaces[4] = {0};
+ Datum values[4] = {0};
+ bool nulls[4] = {0};
int nreplaces = 0;
ctup = SearchSysCache1(RELOID, ObjectIdGetDatum(reloid));
@@ -217,6 +229,11 @@ relation_statistics_update(FunctionCallInfo fcinfo, int elevel, bool inplace)
replaces[nreplaces] = Anum_pg_class_relallvisible;
values[nreplaces] = Int32GetDatum(relallvisible);
nreplaces++;
+
+ /* See comment above in-place update of relallfrozen */
+ replaces[nreplaces] = Anum_pg_class_relallfrozen;
+ values[nreplaces] = Int32GetDatum(-1);
+ nreplaces++;
}
if (nreplaces > 0)
diff --git a/src/backend/utils/cache/relcache.c b/src/backend/utils/cache/relcache.c
index 43219a9629c..efd6bcb3860 100644
--- a/src/backend/utils/cache/relcache.c
+++ b/src/backend/utils/cache/relcache.c
@@ -1925,6 +1925,7 @@ formrdesc(const char *relationName, Oid relationReltype,
relation->rd_rel->relpages = 0;
relation->rd_rel->reltuples = -1;
relation->rd_rel->relallvisible = 0;
+ relation->rd_rel->relallfrozen = 0;
relation->rd_rel->relkind = RELKIND_RELATION;
relation->rd_rel->relnatts = (int16) natts;
@@ -3882,6 +3883,7 @@ RelationSetNewRelfilenumber(Relation relation, char persistence)
classform->relpages = 0; /* it's empty until further notice */
classform->reltuples = -1;
classform->relallvisible = 0;
+ classform->relallfrozen = 0;
}
classform->relfrozenxid = freezeXid;
classform->relminmxid = minmulti;
diff --git a/src/include/catalog/pg_class.h b/src/include/catalog/pg_class.h
index f0d612ca487..fbf42b0e195 100644
--- a/src/include/catalog/pg_class.h
+++ b/src/include/catalog/pg_class.h
@@ -68,6 +68,14 @@ CATALOG(pg_class,1259,RelationRelationId) BKI_BOOTSTRAP BKI_ROWTYPE_OID(83,Relat
/* # of all-visible blocks (not always up-to-date) */
int32 relallvisible BKI_DEFAULT(0);
+ /*
+ * # of all-frozen blocks (not always up-to-date)
+ * Starts as 0 (if it has never been updated).
+ * If relallvisible is manually updated, relallfrozen will be
+ * -1, meaning "unknown"
+ */
+ int32 relallfrozen BKI_DEFAULT(0);
+
/* OID of toast table; 0 if none */
Oid reltoastrelid BKI_DEFAULT(0) BKI_LOOKUP_OPT(pg_class);
diff --git a/src/include/commands/vacuum.h b/src/include/commands/vacuum.h
index 12d0b61950d..b2a678df09e 100644
--- a/src/include/commands/vacuum.h
+++ b/src/include/commands/vacuum.h
@@ -329,6 +329,7 @@ extern void vac_update_relstats(Relation relation,
BlockNumber num_pages,
double num_tuples,
BlockNumber num_all_visible_pages,
+ BlockNumber num_all_frozen_pages,
bool hasindex,
TransactionId frozenxid,
MultiXactId minmulti,
--
2.45.2
On Thu, Jan 16, 2025 at 5:50 PM Melanie Plageman
<melanieplageman@gmail.com> wrote:
On Thu, Jan 16, 2025 at 4:43 PM Melanie Plageman
<melanieplageman@gmail.com> wrote:On Fri, Oct 25, 2024 at 11:14 AM Melanie Plageman
<melanieplageman@gmail.com> wrote:I've done something similar to this in attached v2.
This needed a rebase. See attached v4.
Whoops -- docs didn't build. Attached v5.
Outside of the positive performance impact of vacuuming pages before
they go cold (detailed in my first email [1]/messages/by-id/CAAKRu_aj-P7YyBz_cPNwztz6ohP+vWis=iz3YcomkB3NpYA--w@mail.gmail.com), there is also a
substantial positive effect with this patch for large tables with
substantial cold regions: fewer anti-wraparound vacuums and more
frequent normal/aggressive vacuums
With the default vacuum settings, you often see an append-only table
devolve to _only_ anti-wraparound vacuums after the first aggressive
vacuum. I ran an insert-only workload for an hour (with 32 clients and
synchronous commit off to maximize the amount of data inserted) with
the default vacuum settings. On master, after the first aggressive
vacuum, we do only anti-wraparound vacuums (and only two of these are
triggered). With the patch, after the first aggressive vacuum, 10 more
vacuums are triggered -- none of which are anti-wraparound vacuums.
I attached a chart comparing the autovacuums triggered on master vs
with the patch.
Besides the performance benefit of spreading the freezing work over
more normal vacuums (thereby disrupting foreground workloads less),
anti-wraparound vacuums are not auto canceled by DDL -- making them
more of a nuisance to users.
[1]: /messages/by-id/CAAKRu_aj-P7YyBz_cPNwztz6ohP+vWis=iz3YcomkB3NpYA--w@mail.gmail.com
Attachments:
autovacuums.pngimage/png; name=autovacuums.pngDownload
�PNG
IHDR � � gC� 9tEXtSoftware Matplotlib version3.9.1, https://matplotlib.org/��! pHYs .# .#x�?v IDATx���y��u�?��5���B"���X$�.���@��w�V_�K)O������_.������R�)���� "���3,3�0����x��:30��a�s8���z/��Ncy�I*�N� r$/� 4.
� �)X ��, rJ 9� ��R� @N)� �` �S
� ������Z�bE���K��K�.��i� ;��u�b���������-[���,��K/�'�|r�1 �x������N����z� Y` �SI`���K���������;�4 ��4}��8���3���C�� �z��i��y�����}�&� �O��mK^=� ��$ ��
��71�$$���"��M:E�Q� ��W��_�NA�6T$��~�% �?�#&�+�P�` �.b����k�N�� � ��Y8){.iq���d!Y�-�NP�` �.b��������L�OyI ������N�%���, �T��X>7{�S�d�@}S� ��������m�N&�7X �X0){n�oD~A2Y��)� �]��X��%�rA $��*��)�k
���$ v�t:����N�����R�T���E*�J:
��X23bCE��,vg
�h���t�]�6���c���QUU�t$�H�RQXXeeeQVV���IG �����N%����� �+�N��E�b����q���� �L:���������c���QZZ�����M�&
h�6-���_29 W�� u�N�c���l�2�W�.a��51g����aC�Q �h��X}���� ���������� d�����s�*� je������:�K&�JA���-Z�������h��y���FAAA�R���Auuul��!������<���3��[�..\{��g� ��d�����8�m�d�@�(��AI���r����T*{��g4k�,�T@c��I�(--��m�����c�����V�Z7n����
������#�����K: ����kc���Yk���$D�.]"�Je��Y�&�D @C�pr���o29 �`�����g�EEE����5i�$JJJ��V�^�P �!�X����������� �e�B����'� ��e|
� ��X2=�j]�Z���d�\R�E��N����*k���4�4 �JJJ���7F:�N(
�P���=��Q�2�(�S
�h0���7[+((H �����7[���- ��[�IV�~���\S�E��N�7[K�R $���~m�� ��-��=w��L�5X ���K"�f�u��L�5X ������&%m�'�rM $`����C����d�@�$ ��X�0���#*V&��]�����N���IP� ���F<���5K�N���S��@��% �1X0I� ��Q��, ��Z�t ve}��(j�t
���� 4FMJ"��t
v���}t�) �` $��u�1?I: @2�� @�� ��R�@��w�}�J�2������#
�, rJ 9� ��R� @N)� �
� �� &�G}����������C�����m�����W_}5�L��V��V�Z�����
�����X]�zuL�<9>���X�tiTTTDYYY���q�A�>��S�{?o��U�������Sc���n��())�V�Z�^{�}��������;;b��9��[o���~��/�������C|��_�:���6n�����Y�f���c�����o�8��v�; ��`���c���!C2�UW]W_}ul��1n�����o~}��f�JJJ�{��^\s�5QTT����U���������+���7;��m����������Q�i���C=�<�L���[QUU���:t�/�0~��D�V�jt�g�y��������'�����oso���c��aq��F�>}2��f�����o������������;g��{���V?_�~}�y������.>���-�I�Rq���W\����w���W_�G���c�������e������x >����3����, �X@��f�������?��V��]�6n���?~|<���Q\\3f����;n��Y�Y�xq����OL�4)~��_m3�����8��k���O>����*~������>�rH���p�
����4���k��������&��������q��z��7b��1s��m�K����[o�I'�'�xb<��CQZZZ��&N���
��52 ��% ��t�y��Y�W�:u����G�>}"???k�+��_|qDD,Z�(��)�J�R��G�8��C�G���u��������m�����l���8��g�8��������{�����1=��<xpL�2e����{���/�|�������~���zh������K�H�R��og��?�C�����I�&��W�0`@����QPP����C�n������;7�9�������;�����O��� �R��-
�����f����#F�W\�{��|�t�����+��;����}����� .����3gN��Q���/�:d�M�:5�?��x���3k�^zi�~��QXX��L���q�������c�����G��
�V�ZO<�D\s�51m����X�vm�92�y���W�[�.F���v������_t�f�V�Z&L���z*x�������C�<������o�9��e�]G}�V����Z}f���q�gDEEEfm��A���8�8���2�U�V��?W\qE|������o�������w���w7u�e���E�"???�?����{��w�����x���j| Pw
�hT����q���c�������&N�����~��_��~���>o��M�~��QQQ��{oDD���8��3b��)��Y�x���b��A�����W<�������2eJDD|��'���O��'���<|p��1#�u������7�o|�q�������O=�TDDL�81�y��8����x��^�e��e���:+���?n���C����C��?�y��7/�����8��##"6��O�>��j���*�<�������G�W\��B�����w���8���c��!��GED�]w���~x��5z��O?����x�����_��f���{ u� �Fe����Q�vI��m�\�(
��M:�V�q�[,������.���?FuuuDD���������>SRRW\qE�92����Oo� �{����^TT����G��r�������{�Z�5m������.��[M�4�=z�*_m<��#1i���|���W^��s�;w�����q�d�����[������^z��� ���K: @.�R����k���S�N�����n���������'�xb���������[�����u�����_}�{+**�������eG�z����������__�����_�t�I������7��lIII\~��5~ �?
��F��_�b���>5���_���k_�Z���o�\�f�b�����s���U�����{��������oq_�N���x`�g���K���o���O8��h��U��8���3�_�zu����
-Z���[ @�(H: @.|��5���M���������?�8""���ktf������=^}��x���b���Q^^k�����%K�D��m7[:th������#"�W��UTVV���^=z������^}��H���������k��Y��)Sjt��j� P?`����i=-J:�n+���]��J�����d��������5k��������n�u������[�b���t���{n�������y��q��w��Gyd|��_�C=4Z�n]���b��)Y��Q�b��Q;t��e�j��{��;� ��(��QI��EA-���}%rvk�,YC�������Vq�m���|�I�����Z��������o�1R�T����q�q��7�����������K���;W�\Y�}-Z���o u� ��v�f�W]�t�!C�D�>}b�=��f��Eqqq���e������?��Fo���??�p�t�M1q��������8qbL�81����6lX�z�����{�����+V��;���k����p��
��,�{��'b�����y��q��w��#������^��[�T*F�#F��>� ���;vl�����d����?������/��O>�
��[5QRR�5_r�%1l����G�;t �=X 9���g����oc��5:�l��:���O����O\|���N���?���{.y��x��W3�V�Z_���c����Y�:��%{��G���c�8��#w� ��o����"6T&�jg��� �:`�����3�o��M�~��5>;y����!�JE����w��q���+����rJ,Y�$""-Z�����/�)�}�{��Y����: P;+D�����I' vD^� �O?�4�����;���kt���<�~��z�4h�������^}��-�����[G:���;C���_|��� ����e�W�>RZ �F����F�_�������?Deee}D���/��Y��%K�����4k^�vm�����s���/3��1#�~��Z� �uk�N ;���'� 9I hl:t�3g������'��+�e���<3��=zt������U�V[���u�����RS�]vY�}�����K.��;,���ju @DDq��6{%�j�}��/�O�) �� �;��Li�������/�;��s��/^'�pB�X���o\q���W�8��3��`�?���t�r�-Yk|�����7k~��'��������e��7�7�tSL�<9""�M��w\<��#��S���a��x����O>����5: ���q��I� j+/� ��Yg��5�u�]q��g������W�Z��sO|��_��'FDD���k����������s��q���3�<K�.�l_uuu����q��G�c�=�Y/))��#Gn��v��������?���8p`�������_���;�Weee���������eee��q��E�~������i��m��O?�4����\�;w�s�9'�L�R�� ��� � ���G�|<��S�����?�������G�m�6V�X3g�����g��92z���G���[�-����+���������c���QZZk����3g����7;w�-�D����z��~���"���~;�~��-��9sf���^Yk�z��G}4N=��X�|yDD,_�<�������kb�=��:Diii�����%Kb���5�� ��M@���?�1�o��f�����f��<�����{��?����p��X�p�V?/..�_��Wq�l��o}�[1i������#�N�)��!Cb�� 1b���0aB�gK�,�%K�l�|*��.]���m YyI h�Z�l/��r\q�QVV��}}���|0z��h��I���������SO����ow�������nL�2e��W����c���q����W���h��]�8cD����x��7��'���C�n�;��������k��������^[�� �]C*�N����i�����_��<i�����o�������>�(k�g��QPPP�;aWPYY����)S������I�&��S�8��Cb�}��)o��93�N��g���+W�����Y�f��m��o���O�>������]�����s����K���"�5k{��G���+z�����I��"?� 7^�'b�����q���� ��lGz��r $���(�C���7�w���w���w����:th�1 �z��t X ��, r� �
U:��Y�f��������+VD��M�U�V��g�8��C���(�� �X��|��x�����g��_|1�,Y������1l�����K�����;�f������P�t:�C� �K^���}�{��C�8��s����6��""6l��=�X<8�>��(//�QR �][A��7�x#��_��z~~~t��1��o6l���g���+���������/���5�Ud �]��:h��e�92�
�
����g>��qc���+q��W�+���Y��7��s��Gy���}��q�e���� IS�U{��W��g?��#GFqq���������c��1q�E��~���g���c��11d��Z���c�8��#w(; ��"/�
����c���q�y�m���������;�����g��}��� �AP�UC��
�&M���L~~~�5*k��g���� X�l��AY���Kc��� � H��z��U���V�\�@ �]��z6������i�@ �]CA�vw���J���[�h��I���;wn|��'QYY�[��v��E��mwFL ��Q�U����?d��|��x����S�N�p���>�k��b���q�������� W`����z*^~����s�9���l���3�f�����/����:th�{����k�Z� P�G,��t
�1Z� � ��� ��,[�,.������O>9Poo����q�����>_��Ww���-���������wj `���'"��)� @C� �TWW�7����7o^f���,n���Z����{��'�C��~��E�����4V�\3g��1c��]w��q���e����N�q����������w��G��i�
��?&� �sRI �BV=���������Z��o]�t������x��'b��a������m���6m�D�����?�a\{��q���FuuuDD�X�"���o�� "���� ���by� ��]�� u� k'��������e���Q���3����Z��O<�F{��������V�Z�%�\�Y������G�z��5~ �.�ZD�&�hl�
"�q��I' �B�N���f�PED�s�9q�
7���_|q<�����K/e����?����.�(N;��Z��>}z�|��;�} `���_F��7� @C� k'����g�}v�����)��w�}w�R��d���~�U����/FUUU��������v����= yI��3&N;�������u�Q��CE~~~�r:4�lk��U�p���� P
�v�o���������a��>�h4i�$�YJKK�U�VYk�/�i ��Q�������q��W���x����SOEiii"�
��
6$� `k`����S��������g�z���>�l���%����*�.]����m�D� l��:�={vy���h���Z�������O�pj���QUU��
�C���v�f��T*��u�9�$ h `������#��y��e�:w�/��Bt��9�d��sO�<p��())I(
��)���e���QG3f����m�6������{��"�������N>��d� l��Z�jU{��1y���Z��-�������{��w������{�����g^|��8��Sb������;�w�����H���c#�Je~]}��IG �!Ih(�&L�Z��K�,����������V�Zm���������W\qE�v�i1|��8������,k��������;��#x������|�����~{����* @.(����c�n�v��W���1c�������g���q��������;w���[Giii�����9sb�����K�Rq��������:e �o
������������c����?�1�:��� �����m���1z��<xp4o�|������������+�O���
��$��H��9y�k��q��W��W^�t:f����O��s���+���2JKK�U�V��K�0`@�h�"'� vX��T*{��w����IG��NUUU�?>&M���-�-ZD�.]b���QVVV�{W�X�&M��S�����c�����e�h��]r�!��[���-v��+b��q�p��X�dITWWG��-�_�B������]�~c�����o��"???��k���{��o 4D
������cc��!���������:6l����/��[n���ov�i�����}-~��_D���k�����?�p<��s��{�E:����=z��_���w���x���R�-��=:F���sc�����o�������_���v[L�0!6n����<����7������U�V������{.~����[o����{��7�xc�x���� h��� �++V��!C��O~��-�_ED�[�.~�����O<������7��Mt�Aq�M7����Y~�����_���������{��?�08��9rd�?~��W�t:�y�����~����k���Q���c��j�UD��)Sb���q�����n ��+H: @.TWW�i�����Zf�M�6��k������3gFeee�����8��S�����!C�l�����L����S�NQVVUUU�x���;wn��>�
���^�k�n'|��3fL�r�)�b���>k��mt��1�4i��-�Y�fEuuu����O~7�|sfn��yt��5���c������]y����o�8��S�� ��(�����?f��tP�r�-q���G*������W��>?���3Q���1r���2eJ�l�r�w7m�4N:��8�������]�n�g�������-����X�`ADD|��'���|'��-�����GD�{���^zif�[��V�u�Y[�����o�6k��8��S����6m������s��>}�d�_�zu�7.y��x������^~���9sfDD|�K_�k��6�����t:/��R\x�����f������b����} ��M��(|V~u����c�=���Y�7k�,�?��2dH|�+_�E�E���T���?��o�}��w�qq�YgE�v���~�6m����n�q�q�QG��o�O<�D|���PEDy����B���#�YM�92�/_��;u��<�L���~[���Y�8�����������>���S�w>+�:��s����������S�T<8^~��8��2e`����'�|2N:��Z}/ �aR�E�����X�t��WqYD*/�[��c�x���7+����={�����{lf��{������QVV����}��*C�V�����}��7���#"������n��V���s�=�����M�6�f���Z�n�[���{�������w��_}^��m��+��/�0����O+� �FB�J���;OL:����F��J:����g?����ow�1�C��_|1""***�����~��;%G��=c��1~����x���w��[s���f��F��q�U]\s�5�,������U���;��[&