On Mon, Feb 24, 2025 at 10:30 PM wenhui qiu <qiuwenhu...@gmail.com> wrote: > > Hi Melanie > > relallvisible. It seems like we should make it consistent. Perhaps we > > should just remove it from heap_vacuum_rel(). Then add an assert in > > all these places to at least protect development mistakes. > I think there's some objection to that.
Could you elaborate a bit? There were new merge conflicts, so v9 is attached. - Melanie
From de1d6c8779a3c4082f41d74f25854970ed1a6190 Mon Sep 17 00:00:00 2001 From: Melanie Plageman <melanieplage...@gmail.com> Date: Mon, 24 Feb 2025 17:27:18 -0500 Subject: [PATCH v9 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: Nathan Bossart <nathandboss...@gmail.com> Reviewed-by: Greg Sabino Mullane <htamf...@gmail.com> Discussion: https://postgr.es/m/flat/Z7ZUWje-e1e_fKeu%40nathan#18ec7b0a585a16a58fe317b4ec42efe0 --- doc/src/sgml/catalogs.sgml | 22 +++ src/backend/access/heap/vacuumlazy.c | 17 ++- src/backend/catalog/heap.c | 2 + src/backend/catalog/index.c | 18 ++- src/backend/catalog/system_functions.sql | 3 +- src/backend/commands/analyze.c | 19 ++- src/backend/commands/cluster.c | 5 + src/backend/commands/vacuum.c | 6 + src/backend/statistics/relation_stats.c | 29 +++- src/backend/utils/cache/relcache.c | 2 + src/include/catalog/pg_class.h | 3 + src/include/catalog/pg_proc.dat | 4 +- src/include/commands/vacuum.h | 1 + src/test/regress/expected/stats_import.out | 148 +++++++++++++-------- src/test/regress/sql/stats_import.sql | 76 ++++++++--- 15 files changed, 260 insertions(+), 95 deletions(-) diff --git a/doc/src/sgml/catalogs.sgml b/doc/src/sgml/catalogs.sgml index ee59a7e15d0..e371cd905f2 100644 --- a/doc/src/sgml/catalogs.sgml +++ b/doc/src/sgml/catalogs.sgml @@ -2066,6 +2066,28 @@ 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 in the visibility map, so internal processes will always + update <structfield>relallfrozen</structfield> to a value less than or + equal to <structfield>relallvisible</structfield>. However, if either + field is updated manually, it is possible for + <structfield>relallfrozen</structfield> to exceed + <structfield>relallvisible</structfield>. This will be corrected the + next time these estimates are updated internally. + </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 1af18a78a2b..ad01d7a2150 100644 --- a/src/backend/access/heap/vacuumlazy.c +++ b/src/backend/access/heap/vacuumlazy.c @@ -623,7 +623,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, @@ -898,10 +899,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. * @@ -910,7 +918,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); @@ -3720,7 +3729,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 956f196fc95..7ef6f0f1cba 100644 --- a/src/backend/catalog/heap.c +++ b/src/backend/catalog/heap.c @@ -924,6 +924,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); @@ -994,6 +995,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 f37b990c81d..e878541f432 100644 --- a/src/backend/catalog/index.c +++ b/src/backend/catalog/index.c @@ -2793,8 +2793,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 @@ -2812,6 +2812,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]; @@ -2851,7 +2852,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; + } } /* @@ -2924,6 +2931,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/catalog/system_functions.sql b/src/backend/catalog/system_functions.sql index 591157b1d1b..d0f84323e0a 100644 --- a/src/backend/catalog/system_functions.sql +++ b/src/backend/catalog/system_functions.sql @@ -640,7 +640,8 @@ CREATE OR REPLACE FUNCTION pg_set_relation_stats(relation regclass, relpages integer DEFAULT NULL, reltuples real DEFAULT NULL, - relallvisible integer DEFAULT NULL) + relallvisible integer DEFAULT NULL, + relallfrozen integer DEFAULT NULL) RETURNS void LANGUAGE INTERNAL CALLED ON NULL INPUT VOLATILE diff --git a/src/backend/commands/analyze.c b/src/backend/commands/analyze.c index cd75954951b..9c4755a96d5 100644 --- a/src/backend/commands/analyze.c +++ b/src/backend/commands/analyze.c @@ -630,12 +630,18 @@ 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); + + /* + * 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 (relallfrozen > relallvisible) + relallfrozen = relallvisible; /* * Update pg_class for table relation. CCI first, in case acquirefunc @@ -646,6 +652,7 @@ do_analyze_rel(Relation onerel, VacuumParams *params, relpages, totalrows, relallvisible, + relallfrozen, hasindex, InvalidTransactionId, InvalidMultiXactId, @@ -662,7 +669,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 +685,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 0239d9bae65..e81c9a8aba3 100644 --- a/src/backend/commands/vacuum.c +++ b/src/backend/commands/vacuum.c @@ -1427,6 +1427,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, @@ -1476,6 +1477,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 66731290a3e..2d5fb4efddb 100644 --- a/src/backend/statistics/relation_stats.c +++ b/src/backend/statistics/relation_stats.c @@ -36,6 +36,7 @@ enum relation_stats_argnum RELPAGES_ARG, RELTUPLES_ARG, RELALLVISIBLE_ARG, + RELALLFROZEN_ARG, NUM_RELATION_STATS_ARGS }; @@ -45,6 +46,7 @@ static struct StatsArgInfo relarginfo[] = [RELPAGES_ARG] = {"relpages", INT4OID}, [RELTUPLES_ARG] = {"reltuples", FLOAT4OID}, [RELALLVISIBLE_ARG] = {"relallvisible", INT4OID}, + [RELALLFROZEN_ARG] = {"relallfrozen", INT4OID}, [NUM_RELATION_STATS_ARGS] = {0} }; @@ -65,11 +67,13 @@ relation_statistics_update(FunctionCallInfo fcinfo, int elevel) bool update_reltuples = false; BlockNumber relallvisible = 0; bool update_relallvisible = false; + BlockNumber relallfrozen = 0; + bool update_relallfrozen = false; 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; if (!PG_ARGISNULL(RELPAGES_ARG)) @@ -98,6 +102,12 @@ relation_statistics_update(FunctionCallInfo fcinfo, int elevel) update_relallvisible = true; } + if (!PG_ARGISNULL(RELALLFROZEN_ARG)) + { + relallfrozen = PG_GETARG_UINT32(RELALLFROZEN_ARG); + update_relallfrozen = true; + } + stats_check_required_arg(fcinfo, relarginfo, RELATION_ARG); reloid = PG_GETARG_OID(RELATION_ARG); @@ -148,6 +158,13 @@ relation_statistics_update(FunctionCallInfo fcinfo, int elevel) nreplaces++; } + if (update_relallfrozen && relallfrozen != pgcform->relallfrozen) + { + replaces[nreplaces] = Anum_pg_class_relallfrozen; + values[nreplaces] = UInt32GetDatum(relallfrozen); + nreplaces++; + } + if (nreplaces > 0) { TupleDesc tupdesc = RelationGetDescr(crel); @@ -186,9 +203,9 @@ pg_set_relation_stats(PG_FUNCTION_ARGS) Datum pg_clear_relation_stats(PG_FUNCTION_ARGS) { - LOCAL_FCINFO(newfcinfo, 4); + LOCAL_FCINFO(newfcinfo, 5); - InitFunctionCallInfoData(*newfcinfo, NULL, 4, InvalidOid, NULL, NULL); + InitFunctionCallInfoData(*newfcinfo, NULL, 5, InvalidOid, NULL, NULL); newfcinfo->args[0].value = PG_GETARG_OID(0); newfcinfo->args[0].isnull = PG_ARGISNULL(0); @@ -198,6 +215,8 @@ pg_clear_relation_stats(PG_FUNCTION_ARGS) newfcinfo->args[2].isnull = false; newfcinfo->args[3].value = UInt32GetDatum(0); newfcinfo->args[3].isnull = false; + newfcinfo->args[4].value = UInt32GetDatum(0); + newfcinfo->args[4].isnull = false; relation_statistics_update(newfcinfo, ERROR); PG_RETURN_VOID(); diff --git a/src/backend/utils/cache/relcache.c b/src/backend/utils/cache/relcache.c index 398114373e9..d1ae761b3f6 100644 --- a/src/backend/utils/cache/relcache.c +++ b/src/backend/utils/cache/relcache.c @@ -1928,6 +1928,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; @@ -3885,6 +3886,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..fa96ba07bf4 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/catalog/pg_proc.dat b/src/include/catalog/pg_proc.dat index af9546de23d..a1b51cc973a 100644 --- a/src/include/catalog/pg_proc.dat +++ b/src/include/catalog/pg_proc.dat @@ -12447,8 +12447,8 @@ descr => 'set statistics on relation', proname => 'pg_set_relation_stats', provolatile => 'v', proisstrict => 'f', proparallel => 'u', prorettype => 'void', - proargtypes => 'regclass int4 float4 int4', - proargnames => '{relation,relpages,reltuples,relallvisible}', + proargtypes => 'regclass int4 float4 int4 int4', + proargnames => '{relation,relpages,reltuples,relallvisible,relallfrozen}', prosrc => 'pg_set_relation_stats' }, { oid => '9945', descr => 'clear statistics on relation', diff --git a/src/include/commands/vacuum.h b/src/include/commands/vacuum.h index 1571a66c6bf..baacc63f590 100644 --- a/src/include/commands/vacuum.h +++ b/src/include/commands/vacuum.h @@ -349,6 +349,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, diff --git a/src/test/regress/expected/stats_import.out b/src/test/regress/expected/stats_import.out index d6713eacc2c..944fec03050 100644 --- a/src/test/regress/expected/stats_import.out +++ b/src/test/regress/expected/stats_import.out @@ -13,12 +13,12 @@ CREATE TABLE stats_import.test( tags text[] ) WITH (autovacuum_enabled = false); -- starting stats -SELECT relpages, reltuples, relallvisible +SELECT relpages, reltuples, relallvisible, relallfrozen FROM pg_class WHERE oid = 'stats_import.test'::regclass; - relpages | reltuples | relallvisible -----------+-----------+--------------- - 0 | -1 | 0 + relpages | reltuples | relallvisible | relallfrozen +----------+-----------+---------------+-------------- + 0 | -1 | 0 | 0 (1 row) -- error: regclass not found @@ -27,7 +27,8 @@ SELECT relation => 0::Oid, relpages => 17::integer, reltuples => 400.0::real, - relallvisible => 4::integer); + relallvisible => 4::integer, + relallfrozen => 2::integer); ERROR: could not open relation with OID 0 -- relpages default SELECT @@ -35,7 +36,8 @@ SELECT relation => 'stats_import.test'::regclass, relpages => NULL::integer, reltuples => 400.0::real, - relallvisible => 4::integer); + relallvisible => 4::integer, + relallfrozen => 2::integer); pg_set_relation_stats ----------------------- @@ -47,7 +49,8 @@ SELECT relation => 'stats_import.test'::regclass, relpages => 17::integer, reltuples => NULL::real, - relallvisible => 4::integer); + relallvisible => 4::integer, + relallfrozen => 2::integer); pg_set_relation_stats ----------------------- @@ -59,7 +62,21 @@ SELECT relation => 'stats_import.test'::regclass, relpages => 17::integer, reltuples => 400.0::real, - relallvisible => NULL::integer); + relallvisible => NULL::integer, + relallfrozen => 2::integer); + pg_set_relation_stats +----------------------- + +(1 row) + +-- relallfrozen default +SELECT + pg_catalog.pg_set_relation_stats( + relation => 'stats_import.test'::regclass, + relpages => 17::integer, + reltuples => 400.0::real, + relallvisible => 4::integer, + relallfrozen => NULL::integer); pg_set_relation_stats ----------------------- @@ -71,18 +88,19 @@ SELECT relation => 'stats_import.test'::regclass, relpages => 17::integer, reltuples => 400.0::real, - relallvisible => 4::integer); + relallvisible => 4::integer, + relallfrozen => 2::integer); pg_set_relation_stats ----------------------- (1 row) -SELECT relpages, reltuples, relallvisible +SELECT relpages, reltuples, relallvisible, relallfrozen FROM pg_class WHERE oid = 'stats_import.test'::regclass; - relpages | reltuples | relallvisible -----------+-----------+--------------- - 17 | 400 | 4 + relpages | reltuples | relallvisible | relallfrozen +----------+-----------+---------------+-------------- + 17 | 400 | 4 | 2 (1 row) CREATE INDEX test_i ON stats_import.test(id); @@ -129,18 +147,19 @@ SELECT 'stats_import.test'::regclass, 18::integer, 401.0::real, - 5::integer); + 5::integer, + 3::integer); pg_set_relation_stats ----------------------- (1 row) -SELECT relpages, reltuples, relallvisible +SELECT relpages, reltuples, relallvisible, relallfrozen FROM pg_class WHERE oid = 'stats_import.test'::regclass; - relpages | reltuples | relallvisible -----------+-----------+--------------- - 18 | 401 | 5 + relpages | reltuples | relallvisible | relallfrozen +----------+-----------+---------------+-------------- + 18 | 401 | 5 | 3 (1 row) SELECT relpages, reltuples, relallvisible @@ -160,12 +179,12 @@ SELECT (1 row) -SELECT relpages, reltuples, relallvisible +SELECT relpages, reltuples, relallvisible, relallfrozen FROM pg_class WHERE oid = 'stats_import.test'::regclass; - relpages | reltuples | relallvisible -----------+-----------+--------------- - 0 | -1 | 0 + relpages | reltuples | relallvisible | relallfrozen +----------+-----------+---------------+-------------- + 0 | -1 | 0 | 0 (1 row) -- invalid relkinds for statistics @@ -755,7 +774,8 @@ SELECT pg_restore_relation_stats( 'version', 150000::integer, NULL, '17'::integer, 'reltuples', 400::real, - 'relallvisible', 4::integer); + 'relallvisible', 4::integer, + 'relallfrozen', 2::integer); ERROR: name at variadic position 5 is NULL -- reject: argument name is an integer SELECT pg_restore_relation_stats( @@ -763,7 +783,8 @@ SELECT pg_restore_relation_stats( 'version', 150000::integer, 17, '17'::integer, 'reltuples', 400::real, - 'relallvisible', 4::integer); + 'relallvisible', 4::integer, + 'relallfrozen', 2::integer); ERROR: name at variadic position 5 has type "integer", expected type "text" -- reject: odd number of variadic arguments cannot be pairs SELECT pg_restore_relation_stats( @@ -771,6 +792,7 @@ SELECT pg_restore_relation_stats( 'version', 150000::integer, 'relpages', '17'::integer, 'reltuples', 400::real, + 'relallfrozen', 2::integer, 'relallvisible'); ERROR: variadic arguments must be name/value pairs HINT: Provide an even number of variadic arguments that can be divided into pairs. @@ -780,7 +802,8 @@ SELECT pg_restore_relation_stats( 'version', 150000::integer, 'relpages', '17'::integer, 'reltuples', 400::real, - 'relallvisible', 4::integer); + 'relallvisible', 4::integer, + 'relallfrozen', 2::integer); ERROR: could not open relation with OID 0 -- ok: set all stats SELECT pg_restore_relation_stats( @@ -788,18 +811,19 @@ SELECT pg_restore_relation_stats( 'version', 150000::integer, 'relpages', '17'::integer, 'reltuples', 400::real, - 'relallvisible', 4::integer); + 'relallvisible', 4::integer, + 'relallfrozen', 2::integer); pg_restore_relation_stats --------------------------- t (1 row) -SELECT relpages, reltuples, relallvisible +SELECT relpages, reltuples, relallvisible, relallfrozen FROM pg_class WHERE oid = 'stats_import.test'::regclass; - relpages | reltuples | relallvisible -----------+-----------+--------------- - 17 | 400 | 4 + relpages | reltuples | relallvisible | relallfrozen +----------+-----------+---------------+-------------- + 17 | 400 | 4 | 2 (1 row) -- ok: just relpages @@ -812,12 +836,12 @@ SELECT pg_restore_relation_stats( t (1 row) -SELECT relpages, reltuples, relallvisible +SELECT relpages, reltuples, relallvisible, relallfrozen FROM pg_class WHERE oid = 'stats_import.test'::regclass; - relpages | reltuples | relallvisible -----------+-----------+--------------- - 16 | 400 | 4 + relpages | reltuples | relallvisible | relallfrozen +----------+-----------+---------------+-------------- + 16 | 400 | 4 | 2 (1 row) -- ok: just reltuples @@ -830,12 +854,12 @@ SELECT pg_restore_relation_stats( t (1 row) -SELECT relpages, reltuples, relallvisible +SELECT relpages, reltuples, relallvisible, relallfrozen FROM pg_class WHERE oid = 'stats_import.test'::regclass; - relpages | reltuples | relallvisible -----------+-----------+--------------- - 16 | 500 | 4 + relpages | reltuples | relallvisible | relallfrozen +----------+-----------+---------------+-------------- + 16 | 500 | 4 | 2 (1 row) -- ok: just relallvisible @@ -848,12 +872,30 @@ SELECT pg_restore_relation_stats( t (1 row) -SELECT relpages, reltuples, relallvisible +SELECT relpages, reltuples, relallvisible, relallfrozen FROM pg_class WHERE oid = 'stats_import.test'::regclass; - relpages | reltuples | relallvisible -----------+-----------+--------------- - 16 | 500 | 5 + relpages | reltuples | relallvisible | relallfrozen +----------+-----------+---------------+-------------- + 16 | 500 | 5 | 2 +(1 row) + +-- ok: just relallfrozen +SELECT pg_restore_relation_stats( + 'relation', 'stats_import.test'::regclass, + 'version', 150000::integer, + 'relallfrozen', 3::integer); + pg_restore_relation_stats +--------------------------- + t +(1 row) + +SELECT relpages, reltuples, relallvisible, relallfrozen +FROM pg_class +WHERE oid = 'stats_import.test'::regclass; + relpages | reltuples | relallvisible | relallfrozen +----------+-----------+---------------+-------------- + 16 | 500 | 5 | 3 (1 row) -- warn and error: unrecognized argument name @@ -871,19 +913,20 @@ SELECT pg_restore_relation_stats( 'version', 150000::integer, 'relpages', 'nope'::text, 'reltuples', 400.0::real, - 'relallvisible', 4::integer); + 'relallvisible', 4::integer, + 'relallfrozen', 2::integer); WARNING: argument "relpages" has type "text", expected type "integer" pg_restore_relation_stats --------------------------- f (1 row) -SELECT relpages, reltuples, relallvisible +SELECT relpages, reltuples, relallvisible, relallfrozen FROM pg_class WHERE oid = 'stats_import.test'::regclass; - relpages | reltuples | relallvisible -----------+-----------+--------------- - 16 | 400 | 4 + relpages | reltuples | relallvisible | relallfrozen +----------+-----------+---------------+-------------- + 16 | 400 | 4 | 2 (1 row) -- error: object does not exist @@ -1457,7 +1500,8 @@ SELECT * FROM pg_catalog.pg_restore_relation_stats( 'version', '180000'::integer, 'relpages', '11'::integer, 'reltuples', '10000'::real, - 'relallvisible', '0'::integer + 'relallvisible', '0'::integer, + 'relallfrozen', '0'::integer ); pg_restore_relation_stats --------------------------- @@ -1641,12 +1685,12 @@ WHERE s.starelid = 'stats_import.is_odd'::regclass; (0 rows) -- -SELECT relpages, reltuples, relallvisible +SELECT relpages, reltuples, relallvisible, relallfrozen FROM pg_class WHERE oid = 'stats_import.test'::regclass; - relpages | reltuples | relallvisible -----------+-----------+--------------- - 1 | 4 | 0 + relpages | reltuples | relallvisible | relallfrozen +----------+-----------+---------------+-------------- + 1 | 4 | 0 | 0 (1 row) -- diff --git a/src/test/regress/sql/stats_import.sql b/src/test/regress/sql/stats_import.sql index 9740ab3ff02..dc909003784 100644 --- a/src/test/regress/sql/stats_import.sql +++ b/src/test/regress/sql/stats_import.sql @@ -16,7 +16,7 @@ CREATE TABLE stats_import.test( ) WITH (autovacuum_enabled = false); -- starting stats -SELECT relpages, reltuples, relallvisible +SELECT relpages, reltuples, relallvisible, relallfrozen FROM pg_class WHERE oid = 'stats_import.test'::regclass; @@ -26,7 +26,8 @@ SELECT relation => 0::Oid, relpages => 17::integer, reltuples => 400.0::real, - relallvisible => 4::integer); + relallvisible => 4::integer, + relallfrozen => 2::integer); -- relpages default SELECT @@ -34,7 +35,8 @@ SELECT relation => 'stats_import.test'::regclass, relpages => NULL::integer, reltuples => 400.0::real, - relallvisible => 4::integer); + relallvisible => 4::integer, + relallfrozen => 2::integer); -- reltuples default SELECT @@ -42,7 +44,8 @@ SELECT relation => 'stats_import.test'::regclass, relpages => 17::integer, reltuples => NULL::real, - relallvisible => 4::integer); + relallvisible => 4::integer, + relallfrozen => 2::integer); -- relallvisible default SELECT @@ -50,7 +53,17 @@ SELECT relation => 'stats_import.test'::regclass, relpages => 17::integer, reltuples => 400.0::real, - relallvisible => NULL::integer); + relallvisible => NULL::integer, + relallfrozen => 2::integer); + +-- relallfrozen default +SELECT + pg_catalog.pg_set_relation_stats( + relation => 'stats_import.test'::regclass, + relpages => 17::integer, + reltuples => 400.0::real, + relallvisible => 4::integer, + relallfrozen => NULL::integer); -- named arguments SELECT @@ -58,9 +71,10 @@ SELECT relation => 'stats_import.test'::regclass, relpages => 17::integer, reltuples => 400.0::real, - relallvisible => 4::integer); + relallvisible => 4::integer, + relallfrozen => 2::integer); -SELECT relpages, reltuples, relallvisible +SELECT relpages, reltuples, relallvisible, relallfrozen FROM pg_class WHERE oid = 'stats_import.test'::regclass; @@ -94,9 +108,10 @@ SELECT 'stats_import.test'::regclass, 18::integer, 401.0::real, - 5::integer); + 5::integer, + 3::integer); -SELECT relpages, reltuples, relallvisible +SELECT relpages, reltuples, relallvisible, relallfrozen FROM pg_class WHERE oid = 'stats_import.test'::regclass; @@ -109,7 +124,7 @@ SELECT pg_catalog.pg_clear_relation_stats( 'stats_import.test'::regclass); -SELECT relpages, reltuples, relallvisible +SELECT relpages, reltuples, relallvisible, relallfrozen FROM pg_class WHERE oid = 'stats_import.test'::regclass; @@ -589,7 +604,8 @@ SELECT pg_restore_relation_stats( 'version', 150000::integer, NULL, '17'::integer, 'reltuples', 400::real, - 'relallvisible', 4::integer); + 'relallvisible', 4::integer, + 'relallfrozen', 2::integer); -- reject: argument name is an integer SELECT pg_restore_relation_stats( @@ -597,7 +613,8 @@ SELECT pg_restore_relation_stats( 'version', 150000::integer, 17, '17'::integer, 'reltuples', 400::real, - 'relallvisible', 4::integer); + 'relallvisible', 4::integer, + 'relallfrozen', 2::integer); -- reject: odd number of variadic arguments cannot be pairs SELECT pg_restore_relation_stats( @@ -605,6 +622,7 @@ SELECT pg_restore_relation_stats( 'version', 150000::integer, 'relpages', '17'::integer, 'reltuples', 400::real, + 'relallfrozen', 2::integer, 'relallvisible'); -- reject: object doesn't exist @@ -613,7 +631,8 @@ SELECT pg_restore_relation_stats( 'version', 150000::integer, 'relpages', '17'::integer, 'reltuples', 400::real, - 'relallvisible', 4::integer); + 'relallvisible', 4::integer, + 'relallfrozen', 2::integer); -- ok: set all stats SELECT pg_restore_relation_stats( @@ -621,9 +640,10 @@ SELECT pg_restore_relation_stats( 'version', 150000::integer, 'relpages', '17'::integer, 'reltuples', 400::real, - 'relallvisible', 4::integer); + 'relallvisible', 4::integer, + 'relallfrozen', 2::integer); -SELECT relpages, reltuples, relallvisible +SELECT relpages, reltuples, relallvisible, relallfrozen FROM pg_class WHERE oid = 'stats_import.test'::regclass; @@ -633,7 +653,7 @@ SELECT pg_restore_relation_stats( 'version', 150000::integer, 'relpages', '16'::integer); -SELECT relpages, reltuples, relallvisible +SELECT relpages, reltuples, relallvisible, relallfrozen FROM pg_class WHERE oid = 'stats_import.test'::regclass; @@ -643,7 +663,7 @@ SELECT pg_restore_relation_stats( 'version', 150000::integer, 'reltuples', '500'::real); -SELECT relpages, reltuples, relallvisible +SELECT relpages, reltuples, relallvisible, relallfrozen FROM pg_class WHERE oid = 'stats_import.test'::regclass; @@ -653,7 +673,17 @@ SELECT pg_restore_relation_stats( 'version', 150000::integer, 'relallvisible', 5::integer); -SELECT relpages, reltuples, relallvisible +SELECT relpages, reltuples, relallvisible, relallfrozen +FROM pg_class +WHERE oid = 'stats_import.test'::regclass; + +-- ok: just relallfrozen +SELECT pg_restore_relation_stats( + 'relation', 'stats_import.test'::regclass, + 'version', 150000::integer, + 'relallfrozen', 3::integer); + +SELECT relpages, reltuples, relallvisible, relallfrozen FROM pg_class WHERE oid = 'stats_import.test'::regclass; @@ -671,9 +701,10 @@ SELECT pg_restore_relation_stats( 'version', 150000::integer, 'relpages', 'nope'::text, 'reltuples', 400.0::real, - 'relallvisible', 4::integer); + 'relallvisible', 4::integer, + 'relallfrozen', 2::integer); -SELECT relpages, reltuples, relallvisible +SELECT relpages, reltuples, relallvisible, relallfrozen FROM pg_class WHERE oid = 'stats_import.test'::regclass; @@ -1094,7 +1125,8 @@ SELECT * FROM pg_catalog.pg_restore_relation_stats( 'version', '180000'::integer, 'relpages', '11'::integer, 'reltuples', '10000'::real, - 'relallvisible', '0'::integer + 'relallvisible', '0'::integer, + 'relallfrozen', '0'::integer ); -- Generate statistics on table with data @@ -1249,7 +1281,7 @@ JOIN pg_attribute a ON a.attrelid = s.starelid AND a.attnum = s.staattnum WHERE s.starelid = 'stats_import.is_odd'::regclass; -- -SELECT relpages, reltuples, relallvisible +SELECT relpages, reltuples, relallvisible, relallfrozen FROM pg_class WHERE oid = 'stats_import.test'::regclass; -- 2.34.1
From 59f301f9145622a91908c63b88354785ecfb69b2 Mon Sep 17 00:00:00 2001 From: Melanie Plageman <melanieplage...@gmail.com> Date: Thu, 16 Jan 2025 16:31:55 -0500 Subject: [PATCH v9 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 | 27 ++++++++++++++++--- src/backend/utils/misc/postgresql.conf.sample | 4 +-- 3 files changed, 34 insertions(+), 13 deletions(-) diff --git a/doc/src/sgml/config.sgml b/doc/src/sgml/config.sgml index a8354576108..9d8e42cd3db 100644 --- a/doc/src/sgml/config.sgml +++ b/doc/src/sgml/config.sgml @@ -8745,14 +8745,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 <literal>0.2</literal> (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 ddb303f5201..0aca7d78b90 100644 --- a/src/backend/postmaster/autovacuum.c +++ b/src/backend/postmaster/autovacuum.c @@ -2938,7 +2938,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, @@ -3052,7 +3051,11 @@ 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; + vactuples = tabentry->dead_tuples; instuples = tabentry->ins_since_vacuum; anltuples = tabentry->mod_since_analyze; @@ -3061,11 +3064,29 @@ relation_needs_vacanalyze(Oid relid, if (reltuples < 0) reltuples = 0; + /* + * If we have data for relallfrozen, 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 (relpages > 0 && relallfrozen > 0) + { + /* + * It could be the stats were updated manually and relallfrozen > + * relpages. Clamp relallfrozen to relpages to avoid nonsensical + * calculations. + */ + relallfrozen = Min(relallfrozen, relpages); + pcnt_unfrozen = 1 - ((float4) relallfrozen / relpages); + } + vacthresh = (float4) vac_base_thresh + vac_scale_factor * reltuples; if (vac_max_thresh >= 0 && vacthresh > (float4) vac_max_thresh) vacthresh = (float4) vac_max_thresh; - 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 e771d87da1f..13bd844b66c 100644 --- a/src/backend/utils/misc/postgresql.conf.sample +++ b/src/backend/utils/misc/postgresql.conf.sample @@ -674,8 +674,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_vacuum_max_threshold = 100000000 # max number of row updates # before vacuum; -1 disables max -- 2.34.1