From 55cefadde874e52b57f7b3c2232744e331f9d6bb Mon Sep 17 00:00:00 2001 From: Amit Kapila Date: Wed, 12 Nov 2025 08:38:32 +0000 Subject: [PATCH] Doc: Add documentation for sequence synchronization. Add documentation describing sequence synchronization support in logical replication. It explains how sequence changes are synchronized from the publisher to the subscriber, the configuration requirements, and provide examples illustrating setup and usage. Additionally, document the pg_get_sequence_data() function, which allows users to query sequence details on the publisher to determine when to refresh corresponding sequences on the subscriber. Author: Vignesh C Reviewed-by: Peter Smith Reviewed-by: shveta malik Reviewed-by: Chao Li Reviewed-by: Amit Kapila Discussion: https://postgr.es/m/CAA4eK1LC+KJiAkSrpE_NwvNdidw9F2os7GERUeSxSKv71gXysQ@mail.gmail.com --- doc/src/sgml/catalogs.sgml | 2 +- doc/src/sgml/config.sgml | 16 +- doc/src/sgml/func/func-sequence.sgml | 28 +++ doc/src/sgml/logical-replication.sgml | 294 ++++++++++++++++++++-- doc/src/sgml/monitoring.sgml | 5 +- doc/src/sgml/ref/alter_subscription.sgml | 15 ++ doc/src/sgml/ref/create_subscription.sgml | 31 ++- 7 files changed, 350 insertions(+), 41 deletions(-) diff --git a/doc/src/sgml/catalogs.sgml b/doc/src/sgml/catalogs.sgml index 6c8a0f173c9..2fc63442980 100644 --- a/doc/src/sgml/catalogs.sgml +++ b/doc/src/sgml/catalogs.sgml @@ -6568,7 +6568,7 @@ SCRAM-SHA-256$<iteration count>:&l (references pg_class.oid) - Reference to relation + Reference to table or sequence diff --git a/doc/src/sgml/config.sgml b/doc/src/sgml/config.sgml index 683f7c36f46..d7e48f61905 100644 --- a/doc/src/sgml/config.sgml +++ b/doc/src/sgml/config.sgml @@ -5199,8 +5199,8 @@ ANY num_sync ( num_sync ( num_sync ( + + pg_get_sequence_data + + pg_get_sequence_data ( regclass ) + record + ( last_value bigint, + is_called bool, + page_lsn pg_lsn ) + + + Returns information about the sequence. + last_value is the last sequence value + written to disk. If caching is used, this value can be greater than the + last value handed out from the sequence. + is_called indicates whether the sequence has + been used. page_lsn is the LSN corresponding + to the most recent WAL record that modified this sequence relation. + + + This function is primarily intended for internal use by pg_dump and by + logical replication to synchronize sequences. It requires + USAGE or SELECT privilege on the + sequence. + + diff --git a/doc/src/sgml/logical-replication.sgml b/doc/src/sgml/logical-replication.sgml index d64ed9dc36b..79ecd09614f 100644 --- a/doc/src/sgml/logical-replication.sgml +++ b/doc/src/sgml/logical-replication.sgml @@ -113,7 +113,9 @@ Publications may currently only contain tables or sequences. Objects must be added explicitly, except when a publication is created using FOR TABLES IN SCHEMA, FOR ALL TABLES, - or FOR ALL SEQUENCES. + or FOR ALL SEQUENCES. Unlike tables, sequences can be + synchronized at any time. For more information, see + . @@ -1745,6 +1747,247 @@ Publications: + + Replicating Sequences + + + To synchronize sequences from a publisher to a subscriber, first publish + them using + CREATE PUBLICATION ... FOR ALL SEQUENCES and then + on the subscriber: + + + + + + + use CREATE SUBSCRIPTION + to initially synchronize the published sequences. + + + + + use + ALTER SUBSCRIPTION ... REFRESH PUBLICATION + to synchronize only newly added sequences. + + + + + use + ALTER SUBSCRIPTION ... REFRESH SEQUENCES + to re-synchronize all sequences currently known to the subscription. + + + + + + + A sequence synchronization worker will be started + after executing any of the above subscriber commands, and will exit once the + sequences are synchronized. + + + The ability to launch a sequence synchronization worker is limited by the + + max_sync_workers_per_subscription + configuration. + + + + Sequence Definition Mismatches + + The sequence synchronization worker validates that sequence definitions + match between publisher and subscriber. If mismatches exist, the worker + logs an error identifying them and exits. The apply worker continues + respawning the sequence synchronization worker until synchronization + succeeds. See also + wal_retrieve_retry_interval. + + + To resolve this, use + ALTER SEQUENCE + to align the subscriber's sequence parameters with those of the publisher. + + + + + Refreshing Out-of-Sync Sequences + + Subscriber sequence values will become out of sync as the publisher + advances them. + + + To detect this, compare the + pg_subscription_rel.srsublsn + on the subscriber with the page_lsn obtained + from the pg_get_sequence_data + function for the sequence on the publisher. Then run + + ALTER SUBSCRIPTION ... REFRESH SEQUENCES to + re-synchronize if necessary. + + + + Each sequence caches a block of values (typically 32) in memory before + generating a new WAL record, so its LSN advances only after the entire + cached batch has been consumed. As a result, sequence value drift cannot + be detected by LSN comparison when sequence increments fall within the + same cached block (typically 32 values). + + + + + + Examples + + + Create some sequences on the publisher. + +/* pub # */ CREATE SEQUENCE s1 START WITH 10 INCREMENT BY 1; +/* pub # */ CREATE SEQUENCE s2 START WITH 100 INCREMENT BY 10; + + + + Create the same sequences on the subscriber. + +/* sub # */ CREATE SEQUENCE s1 START WITH 10 INCREMENT BY 1; +/* sub # */ CREATE SEQUENCE s2 START WITH 100 INCREMENT BY 10; + + + + Advance the sequences on the publisher a few times. + +/* pub # */ SELECT nextval('s1'); + nextval +--------- + 10 +(1 row) +/* pub # */ SELECT nextval('s1'); + nextval +--------- + 11 +(1 row) +/* pub # */ SELECT nextval('s2'); + nextval +--------- + 100 +(1 row) +/* pub # */ SELECT nextval('s2'); + nextval +--------- + 110 +(1 row) + + + + Check the sequence page LSNs on the publisher. + +/* pub # */ SELECT * FROM pg_get_sequence_data('s1'); + last_value | is_called | page_lsn +------------+-----------+------------ + 11 | t | 0/0178F9E0 +(1 row) +/* pub # */ SELECT * FROM pg_get_sequence_data('s2'); + last_value | is_called | page_lsn +------------+-----------+------------ + 110 | t | 0/0178FAB0 +(1 row) + + + + Create a publication for the sequences. + +/* pub # */ CREATE PUBLICATION pub1 FOR ALL SEQUENCES; + + + + Subscribe to the publication. + +/* sub # */ CREATE SUBSCRIPTION sub1 +/* sub - */ CONNECTION 'host=localhost dbname=test_pub application_name=sub1' +/* sub - */ PUBLICATION pub1; + + + + Verify that the initial sequence values are synchronized. + +/* sub # */ SELECT last_value, is_called FROM s1; + last_value | is_called +------------+----------- + 11 | t +(1 row) + +/* sub # */ SELECT last_value, is_called FROM s2; + last_value | is_called +------------+----------- + 110 | t +(1 row) + + + + Confirm that the sequence page LSNs on the publisher have been recorded + on the subscriber. + +/* sub # */ SELECT srrelid::regclass, srsublsn FROM pg_subscription_rel; + srrelid | srsublsn +---------+------------ + s1 | 0/0178F9E0 + s2 | 0/0178FAB0 +(2 rows) + + + + Advance the sequences on the publisher 50 more times. + +/* pub # */ SELECT nextval('s1') FROM generate_series(1,50); +/* pub # */ SELECT nextval('s2') FROM generate_series(1,50); + + + + Check the sequence page LSNs on the publisher. + +/* pub # */ SELECT * FROM pg_get_sequence_data('s1'); + last_value | is_called | page_lsn +------------+-----------+------------ + 61 | t | 0/017CED28 +(1 row) + +/* pub # */ SELECT * FROM pg_get_sequence_data('s2'); + last_value | is_called | page_lsn +------------+-----------+------------ + 610 | t | 0/017CEDF8 +(1 row) + + + + The difference between the sequence page LSNs on the publisher and the + sequence page LSNs on the subscriber indicates that the sequences are out + of sync. Re-synchronize all sequences known to the subscriber using + + ALTER SUBSCRIPTION ... REFRESH SEQUENCES. + +/* sub # */ ALTER SUBSCRIPTION sub1 REFRESH SEQUENCES; + + + + Recheck the sequences on the subscriber. + +/* sub # */ SELECT last_value, is_called FROM s1; + last_value | is_called +------------+----------- + 61 | t +(1 row) + +/* sub # */ SELECT last_value, is_called FROM s2; + last_value | is_called +------------+----------- + 610 | t +(1 row) + + + + Conflicts @@ -2090,16 +2333,19 @@ CONTEXT: processing remote data for replication origin "pg_16395" during "INSER - Sequence data is not replicated. The data in serial or identity columns - backed by sequences will of course be replicated as part of the table, - but the sequence itself would still show the start value on the - subscriber. If the subscriber is used as a read-only database, then this - should typically not be a problem. If, however, some kind of switchover - or failover to the subscriber database is intended, then the sequences - would need to be updated to the latest values, either by copying the - current data from the publisher (perhaps - using pg_dump) or by determining a sufficiently high - value from the tables themselves. + Incremental sequence changes are not replicated. Although the data in + serial or identity columns backed by sequences will be replicated as part + of the table, the sequences themselves do not replicate ongoing changes. + On the subscriber, a sequence will retain the last value it synchronized + from the publisher. If the subscriber is used as a read-only database, + then this should typically not be a problem. If, however, some kind of + switchover or failover to the subscriber database is intended, then the + sequences would need to be updated to the latest values, either by + executing + ALTER SUBSCRIPTION ... REFRESH SEQUENCES + or by copying the current data from the publisher (perhaps using + pg_dump) or by determining a sufficiently high value + from the tables themselves. @@ -2290,9 +2536,9 @@ CONTEXT: processing remote data for replication origin "pg_16395" during "INSER - In order to be able to copy the initial table data, the role used for the - replication connection must have the SELECT privilege on - a published table (or be a superuser). + In order to be able to copy the initial table or sequence data, the role + used for the replication connection must have the SELECT + privilege on a published table or sequence (or be a superuser). @@ -2303,8 +2549,8 @@ CONTEXT: processing remote data for replication origin "pg_16395" during "INSER To add tables to a publication, the user must have ownership rights on the table. To add all tables in schema to a publication, the user must be a - superuser. To create a publication that publishes all tables or all tables in - schema automatically, the user must be a superuser. + superuser. To create a publication that publishes all tables, all tables in + schema, or all sequences automatically, the user must be a superuser. @@ -2329,8 +2575,11 @@ CONTEXT: processing remote data for replication origin "pg_16395" during "INSER privileges of the subscription owner. However, when performing an insert, update, delete, or truncate operation on a particular table, it will switch roles to the table owner and perform the operation with the table owner's - privileges. This means that the subscription owner needs to be able to - SET ROLE to each role that owns a replicated table. + privileges. Similarly, when synchronizing sequence data, it will switch to + the sequence owner's role and perform the operation using the sequence + owner's privileges. This means that the subscription owner needs to be able + to SET ROLE to each role that owns a replicated table or + sequence. @@ -2423,8 +2672,8 @@ CONTEXT: processing remote data for replication origin "pg_16395" during "INSER max_logical_replication_workers must be set to at least the number of subscriptions (for leader apply - workers), plus some reserve for the table synchronization workers and - parallel apply workers. + workers), plus some reserve for the parallel apply workers, and + table/sequence synchronization workers. @@ -2437,8 +2686,9 @@ CONTEXT: processing remote data for replication origin "pg_16395" during "INSER max_sync_workers_per_subscription - controls the amount of parallelism of the initial data copy during the - subscription initialization or when new tables are added. + controls how many tables can be synchronized in parallel during + subscription initialization or when new tables are added. One additional + worker is also needed for sequence synchronization. diff --git a/doc/src/sgml/monitoring.sgml b/doc/src/sgml/monitoring.sgml index 2741c138593..7b9fa20df9e 100644 --- a/doc/src/sgml/monitoring.sgml +++ b/doc/src/sgml/monitoring.sgml @@ -2045,8 +2045,9 @@ description | Waiting for a newly initialized WAL file to reach durable storage Type of the subscription worker process. Possible types are - apply, parallel apply, and - table synchronization. + apply, parallel apply, + table synchronization, and + sequence synchronization. diff --git a/doc/src/sgml/ref/alter_subscription.sgml b/doc/src/sgml/ref/alter_subscription.sgml index 8ab3b7fbd37..27c06439f4f 100644 --- a/doc/src/sgml/ref/alter_subscription.sgml +++ b/doc/src/sgml/ref/alter_subscription.sgml @@ -195,6 +195,12 @@ ALTER SUBSCRIPTION name RENAME TO < use ALTER SUBSCRIPTION ... REFRESH SEQUENCES. + + See for recommendations on how + to handle any warnings about sequence definition differences between + the publisher and the subscriber, which might occur when + copy_data = true. + See for details of how copy_data = true can interact with the @@ -225,6 +231,15 @@ ALTER SUBSCRIPTION name RENAME TO < data for all currently subscribed sequences. It does not add or remove sequences from the subscription to match the publication. + + See for + recommendations on how to handle any warnings about sequence definition + differences between the publisher and the subscriber. + + + See for recommendations on how to + identify and handle out-of-sync sequences. + diff --git a/doc/src/sgml/ref/create_subscription.sgml b/doc/src/sgml/ref/create_subscription.sgml index ed82cf1809e..197be0c6f6b 100644 --- a/doc/src/sgml/ref/create_subscription.sgml +++ b/doc/src/sgml/ref/create_subscription.sgml @@ -127,10 +127,10 @@ CREATE SUBSCRIPTION subscription_name Since no connection is made when this option is - false, no tables are subscribed. To initiate - replication, you must manually create the replication slot, enable - the failover if required, enable the subscription, and refresh the - subscription. See + false, no tables and sequences are subscribed. To + initiate replication, you must manually create the replication slot, + enable the failover if required, enable the subscription, and refresh + the subscription. See for examples. @@ -228,7 +228,7 @@ CREATE SUBSCRIPTION subscription_name for more about send/receive - functions). + functions). This parameter has no effect for sequences. @@ -265,6 +265,12 @@ CREATE SUBSCRIPTION subscription_namecopy_data = true can interact with the origin parameter. + + See + for recommendations on how to handle any warnings about sequence + definition differences between the publisher and the subscriber, + which might occur when copy_data = true. + @@ -280,6 +286,7 @@ CREATE SUBSCRIPTION subscription_name @@ -310,7 +317,8 @@ CREATE SUBSCRIPTION subscription_name setting within this subscription's apply worker processes. The default value - is off. + is off. This parameter has no effect for + sequences. @@ -340,7 +348,8 @@ CREATE SUBSCRIPTION subscription_name Specifies whether two-phase commit is enabled for this subscription. - The default is false. + The default is false. This parameter has no effect + for sequences. @@ -398,8 +407,8 @@ CREATE SUBSCRIPTION subscription_name If true, all replication actions are performed as the subscription owner. If false, replication workers will perform actions on each - table as the owner of that table. The latter configuration is - generally much more secure; for details, see + table or sequence as the owner of that relation. The latter + configuration is generally much more secure; for details, see . The default is false. @@ -417,6 +426,7 @@ CREATE SUBSCRIPTION subscription_nameorigin to any means that the publisher sends changes regardless of their origin. The default is any. + This parameter has no effect for sequences. See for details of how @@ -449,7 +459,8 @@ CREATE SUBSCRIPTION subscription_name is enabled, and a physical replication slot named pg_conflict_detection is created on the subscriber to prevent the information for detecting - conflicts from being removed. + conflicts from being removed. This parameter has no effect for + sequences.