pg_createsubscriber: creates a new logical replica from a standby server

It must be run on the target server and should be able to connect to
the source server (publisher) and the target server (subscriber).  All
tables in the specified database(s) are included in the logical
replication setup.  A pair of publication and subscription objects are
created for each database.

The main advantage of pg_createsubscriber over the common logical
replication setup is the initial data copy.  It also reduces the
catchup phase.

Some prerequisites must be met to successfully run it.  It is
basically the logical replication requirements.  It starts creating a
publication using FOR ALL TABLES and a replication slot for each
specified database.  Write recovery parameters into the target data
directory and start the target server.  It specifies the LSN of the
last replication slot (replication start point) up to which the
recovery will proceed.  Wait until the target server is promoted.
Create one subscription per specified database (using publication and
replication slot created in a previous step) on the target server.
Set the replication progress to the replication start point for each
subscription.  Enable the subscription for each specified database on
the target server.  And finally, change the system identifier on the
target server.

Author: Euler Taveira <euler.taveira@enterprisedb.com>
Reviewed-by: Hayato Kuroda <kuroda.hayato@fujitsu.com>
Reviewed-by: Amit Kapila <amit.kapila16@gmail.com>
Reviewed-by: Shlok Kyal <shlok.kyal.oss@gmail.com>
Reviewed-by: Vignesh C <vignesh21@gmail.com>
Reviewed-by: Shubham Khanna <khannashubham1197@gmail.com>
Reviewed-by: Ashutosh Bapat <ashutosh.bapat.oss@gmail.com>
Reviewed-by: Peter Eisentraut <peter@eisentraut.org>
Discussion: https://www.postgresql.org/message-id/flat/5ac50071-f2ed-4ace-a8fd-b892cffd33eb@www.fastmail.com
This commit is contained in:
Peter Eisentraut 2024-03-25 12:30:55 +01:00
parent a11f330b55
commit d44032d014
9 changed files with 3059 additions and 3 deletions

View File

@ -205,6 +205,7 @@ Complete list of usable sgml source files in this directory.
<!ENTITY pgCombinebackup SYSTEM "pg_combinebackup.sgml">
<!ENTITY pgConfig SYSTEM "pg_config-ref.sgml">
<!ENTITY pgControldata SYSTEM "pg_controldata.sgml">
<!ENTITY pgCreateSubscriber SYSTEM "pg_createsubscriber.sgml">
<!ENTITY pgCtl SYSTEM "pg_ctl-ref.sgml">
<!ENTITY pgDump SYSTEM "pg_dump.sgml">
<!ENTITY pgDumpall SYSTEM "pg_dumpall.sgml">

View File

@ -0,0 +1,523 @@
<!--
doc/src/sgml/ref/pg_createsubscriber.sgml
PostgreSQL documentation
-->
<refentry id="app-pgcreatesubscriber">
<indexterm zone="app-pgcreatesubscriber">
<primary>pg_createsubscriber</primary>
</indexterm>
<refmeta>
<refentrytitle><application>pg_createsubscriber</application></refentrytitle>
<manvolnum>1</manvolnum>
<refmiscinfo>Application</refmiscinfo>
</refmeta>
<refnamediv>
<refname>pg_createsubscriber</refname>
<refpurpose>convert a physical replica into a new logical replica</refpurpose>
</refnamediv>
<refsynopsisdiv>
<cmdsynopsis>
<command>pg_createsubscriber</command>
<arg rep="repeat"><replaceable>option</replaceable></arg>
<group choice="plain">
<group choice="req">
<arg choice="plain"><option>-d</option></arg>
<arg choice="plain"><option>--database</option></arg>
</group>
<replaceable>dbname</replaceable>
<group choice="req">
<arg choice="plain"><option>-D</option> </arg>
<arg choice="plain"><option>--pgdata</option></arg>
</group>
<replaceable>datadir</replaceable>
<group choice="req">
<arg choice="plain"><option>-P</option></arg>
<arg choice="plain"><option>--publisher-server</option></arg>
</group>
<replaceable>connstr</replaceable>
</group>
</cmdsynopsis>
</refsynopsisdiv>
<refsect1>
<title>Description</title>
<para>
<application>pg_createsubscriber</application> creates a new logical
replica from a physical standby server. All tables in the specified
database are included in the logical replication setup. A pair of
publication and subscription objects are created for each database. It
must be run at the target server.
</para>
<para>
After a successful run, the state of the target server is analogous to a
fresh logical replication setup. The main difference between the logical
replication setup and <application>pg_createsubscriber</application> is the
initial data copy. It does only the synchronization phase, which ensures
each table is brought up to a synchronized state.
</para>
<para>
The <application>pg_createsubscriber</application> targets large database
systems because in logical replication setup, most of the time is spent
doing the initial data copy. Furthermore, a side effect of this long time
spent synchronizing data is usually a large amount of changes to be applied
(that were produced during the initial data copy), which increases even
more the time when the logical replica will be available. For smaller
databases, <link linkend="logical-replication">initial data
synchronization</link> is recommended.
</para>
</refsect1>
<refsect1>
<title>Options</title>
<para>
<application>pg_createsubscriber</application> accepts the following
command-line arguments:
<variablelist>
<varlistentry>
<term><option>-d <replaceable class="parameter">dbname</replaceable></option></term>
<term><option>--database=<replaceable class="parameter">dbname</replaceable></option></term>
<listitem>
<para>
The database name to create the subscription. Multiple databases can
be selected by writing multiple <option>-d</option> switches.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><option>-D <replaceable class="parameter">directory</replaceable></option></term>
<term><option>--pgdata=<replaceable class="parameter">directory</replaceable></option></term>
<listitem>
<para>
The target directory that contains a cluster directory from a physical
replica.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><option>-n</option></term>
<term><option>--dry-run</option></term>
<listitem>
<para>
Do everything except actually modifying the target directory.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><option>-p <replaceable class="parameter">port</replaceable></option></term>
<term><option>--subscriber-port=<replaceable class="parameter">port</replaceable></option></term>
<listitem>
<para>
The port number on which the target server is listening for
connections. Defaults to running the target server on port 50432 to
avoid unintended client connections.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><option>-P <replaceable class="parameter">connstr</replaceable></option></term>
<term><option>--publisher-server=<replaceable class="parameter">connstr</replaceable></option></term>
<listitem>
<para>
The connection string to the publisher. For details see <xref
linkend="libpq-connstring"/>.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><option>-s <replaceable class="parameter">dir</replaceable></option></term>
<term><option>--socket-directory=<replaceable class="parameter">dir</replaceable></option></term>
<listitem>
<para>
The directory to use for postmaster sockets on target server. The
default is current directory.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><option>-t <replaceable class="parameter">seconds</replaceable></option></term>
<term><option>--recovery-timeout=<replaceable class="parameter">seconds</replaceable></option></term>
<listitem>
<para>
The maximum number of seconds to wait for recovery to end. Setting to
0 disables. The default is 0.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><option>-U <replaceable class="parameter">username</replaceable></option></term>
<term><option>--subscriber-username=<replaceable class="parameter">username</replaceable></option></term>
<listitem>
<para>
The user name to connect as on target server. Defaults to the current
operating system user name.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><option>-v</option></term>
<term><option>--verbose</option></term>
<listitem>
<para>
Enables verbose mode. This will cause
<application>pg_createsubscriber</application> to output progress
messages and detailed information about each step to standard error.
Repeating the option causes additional debug-level messages to appear
on standard error.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><option>--config-file=<replaceable class="parameter">filename</replaceable></option></term>
<listitem>
<para>
Use the specified main server configuration file for the target data
directory. The <application>pg_createsubscriber</application> uses
internally the <application>pg_ctl</application> command to start and
stop the target server. It allows you to specify the actual
<filename>postgresql.conf</filename> configuration file if it is stored
outside the data directory.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><option>--publication=<replaceable class="parameter">name</replaceable></option></term>
<listitem>
<para>
The publication name to set up the logical replication. Multiple
publications can be specified by writing multiple
<option>--publication</option> switches. The number of publication
names must match the number of specified databases, otherwise an error
is reported. The order of the multiple publication name switches must
match the order of database switches. If this option is not specified,
a generated name is assigned to the publication name.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><option>--subscription=<replaceable class="parameter">name</replaceable></option></term>
<listitem>
<para>
The subscription name to set up the logical replication. Multiple
subscriptions can be specified by writing multiple
<option>--subscription</option> switches. The number of subscription
names must match the number of specified databases, otherwise an error
is reported. The order of the multiple subscription name switches must
match the order of database switches. If this option is not specified,
a generated name is assigned to the subscription name.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><option>--replication-slot=<replaceable class="parameter">name</replaceable></option></term>
<listitem>
<para>
The replication slot name to set up the logical replication. Multiple
replication slots can be specified by writing multiple
<option>--replication-slot</option> switches. The number of
replication slot names must match the number of specified databases,
otherwise an error is reported. The order of the multiple replication
slot name switches must match the order of database switches. If this
option is not specified, the subscription name is assigned to the
replication slot name.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><option>-?</option></term>
<term><option>--help</option></term>
<listitem>
<para>
Show help about <application>pg_createsubscriber</application> command
line arguments, and exit.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><option>-V</option></term>
<term><option>--version</option></term>
<listitem>
<para>
Print the <application>pg_createsubscriber</application> version and exit.
</para>
</listitem>
</varlistentry>
</variablelist>
</para>
</refsect1>
<refsect1>
<title>Notes</title>
<refsect2>
<title>Prerequisites</title>
<para>
There are some prerequisites for
<application>pg_createsubscriber</application> to convert the target server
into a logical replica. If these are not met, an error will be reported.
The source and target servers must have the same major version as the
<application>pg_createsubscriber</application>. The given target data
directory must have the same system identifier as the source data
directory. The given database user for the target data directory must have
privileges for creating <link
linkend="sql-createsubscription">subscriptions</link> and using <link
linkend="pg-replication-origin-advance"><function>pg_replication_origin_advance()</function></link>.
</para>
<para>
The target server must be used as a physical standby. The target server
must have <xref linkend="guc-max-replication-slots"/> and <xref
linkend="guc-max-logical-replication-workers"/> configured to a value
greater than or equal to the number of specified databases. The target
server must have <xref linkend="guc-max-worker-processes"/> configured to a
value greater than the number of specified databases. The target server
must accept local connections.
</para>
<para>
The source server must accept connections from the target server. The
source server must not be in recovery. The source server must have <xref
linkend="guc-wal-level"/> as <literal>logical</literal>. The source server
must have <xref linkend="guc-max-replication-slots"/> configured to a value
greater than or equal to the number of specified databases plus existing
replication slots. The source server must have <xref
linkend="guc-max-wal-senders"/> configured to a value greater than or equal
to the number of specified databases and existing WAL sender processes.
</para>
</refsect2>
<refsect2>
<title>Warnings</title>
<para>
If <application>pg_createsubscriber</application> fails after the target
server was promoted, then the data directory is likely not in a state that
can be recovered. In such case, creating a new standby server is
recommended.
</para>
<para>
<application>pg_createsubscriber</application> usually starts the target
server with different connection settings during transformation. Hence,
connections to the target server should fail.
</para>
<para>
During the recovery process, if the target server disconnects from the
source server, <application>pg_createsubscriber</application> will check a
few times if the connection has been reestablished to stream the required
WAL. After a few attempts, it terminates with an error.
</para>
<para>
Since DDL commands are not replicated by logical replication, avoid
executing DDL commands that change the database schema while running
<application>pg_createsubscriber</application>. If the target server has
already been converted to logical replica, the DDL commands might not be
replicated, which might cause an error.
</para>
<para>
If <application>pg_createsubscriber</application> fails while processing,
objects (publications, replication slots) created on the source server are
removed. The removal might fail if the target server cannot connect to
the source server. In such a case, a warning message will inform the
objects left. If the target server is running, it will be stopped.
</para>
<para>
If the replication is using <xref linkend="guc-primary-slot-name"/>, it
will be removed from the source server after the logical replication
setup.
</para>
<para>
If the target server is a synchronous replica, transaction commits on the
primary might wait for replication while running
<application>pg_createsubscriber</application>.
</para>
<para>
<application>pg_createsubscriber</application> changes the system
identifier using <application>pg_resetwal</application>. It would avoid
situations in which the target server might use WAL files from the source
server. If the target server has a standby, replication will break and a
fresh standby should be created.
</para>
</refsect2>
<refsect2>
<title>How It Works</title>
<para>
The basic idea is to have a replication start point from the source server
and set up a logical replication to start from this point:
</para>
<procedure>
<step>
<para>
Start the target server with the specified command-line options. If the
target server is already running,
<application>pg_createsubscriber</application> will terminate with an
error.
</para>
</step>
<step>
<para>
Check if the target server can be converted. There are also a few
checks on the source server. If any of the prerequisites are not met,
<application>pg_createsubscriber</application> will terminate with an
error.
</para>
</step>
<step>
<para>
Create a publication and replication slot for each specified database on
the source server. Each publication is created using <link
linkend="sql-createpublication-params-for-all-tables"><literal>FOR ALL
TABLES</literal></link>. If <option>publication-name</option> option is
not specified, it has the following name pattern:
<quote><literal>pg_createsubscriber_%u_%x</literal></quote> (parameter:
database <parameter>oid</parameter>, random <parameter>int</parameter>).
If <option>replication-slot-name</option> is not specified, the
replication slot has the following name pattern:
<quote><literal>pg_createsubscriber_%u_%x</literal></quote> (parameters:
database <parameter>oid</parameter>, random <parameter>int</parameter>).
These replication slots will be used by the subscriptions in a future
step. The last replication slot LSN is used as a stopping point in the
<xref linkend="guc-recovery-target-lsn"/> parameter and by the
subscriptions as a replication start point. It guarantees that no
transaction will be lost.
</para>
</step>
<step>
<para>
Write recovery parameters into the target data directory and restart the
target server. It specifies an LSN (<xref
linkend="guc-recovery-target-lsn"/>) of the write-ahead log location up
to which recovery will proceed. It also specifies
<literal>promote</literal> as the action that the server should take
once the recovery target is reached. Additional <link
linkend="runtime-config-wal-recovery-target">recovery parameters</link>
are added to avoid unexpected behavior during the recovery process such
as end of the recovery as soon as a consistent state is reached (WAL
should be applied until the replication start location) and multiple
recovery targets that can cause a failure. This step finishes once the
server ends standby mode and is accepting read-write transactions. If
<option>--recovery-timeout</option> option is set,
<application>pg_createsubscriber</application> terminates if recovery
does not end until the given number of seconds.
</para>
</step>
<step>
<para>
Create a subscription for each specified database on the target server.
If <option>subscription-name</option> is not specified, the subscription
has the following name pattern:
<quote><literal>pg_createsubscriber_%u_%x</literal></quote> (parameters:
database <parameter>oid</parameter>, random <parameter>int</parameter>).
It does not copy existing data from the source server. It does not
create a replication slot. Instead, it uses the replication slot that
was created in a previous step. The subscription is created but it is
not enabled yet. The reason is the replication progress must be set to
the replication start point before starting the replication.
</para>
</step>
<step>
<para>
Drop publications on the target server that were replicated because they
were created before the replication start location. It has no use on
the subscriber.
</para>
</step>
<step>
<para>
Set the replication progress to the replication start point for each
subscription. When the target server starts the recovery process, it
catches up to the replication start point. This is the exact LSN to be
used as a initial replication location for each subscription. The
replication origin name is obtained since the subscription was created.
The replication origin name and the replication start point are used in
<link
linkend="pg-replication-origin-advance"><function>pg_replication_origin_advance()</function></link>
to set up the initial replication location.
</para>
</step>
<step>
<para>
Enable the subscription for each specified database on the target server.
The subscription starts applying transactions from the replication start
point.
</para>
</step>
<step>
<para>
If the standby server was using <xref linkend="guc-primary-slot-name"/>,
it has no use from now on so drop it.
</para>
</step>
<step>
<para>
Update the system identifier on the target server. The
<xref linkend="app-pgresetwal"/> is run to modify the system identifier.
The target server is stopped as a <command>pg_resetwal</command> requirement.
</para>
</step>
</procedure>
</refsect2>
</refsect1>
<refsect1>
<title>Examples</title>
<para>
To create a logical replica for databases <literal>hr</literal> and
<literal>finance</literal> from a physical replica at
<literal>foo</literal>:
<screen>
<prompt>$</prompt> <userinput>pg_createsubscriber -D /usr/local/pgsql/data -P "host=foo" -d hr -d finance</userinput>
</screen>
</para>
</refsect1>
<refsect1>
<title>See Also</title>
<simplelist type="inline">
<member><xref linkend="app-pgbasebackup"/></member>
</simplelist>
</refsect1>
</refentry>

View File

@ -282,6 +282,7 @@
&pgarchivecleanup;
&pgChecksums;
&pgControldata;
&pgCreateSubscriber;
&pgCtl;
&pgResetwal;
&pgRewind;

View File

@ -1,4 +1,5 @@
/pg_basebackup
/pg_createsubscriber
/pg_receivewal
/pg_recvlogical

View File

@ -44,11 +44,14 @@ BBOBJS = \
bbstreamer_tar.o \
bbstreamer_zstd.o
all: pg_basebackup pg_receivewal pg_recvlogical
all: pg_basebackup pg_createsubscriber pg_receivewal pg_recvlogical
pg_basebackup: $(BBOBJS) $(OBJS) | submake-libpq submake-libpgport submake-libpgfeutils
$(CC) $(CFLAGS) $(BBOBJS) $(OBJS) $(LDFLAGS) $(LDFLAGS_EX) $(LIBS) -o $@$(X)
pg_createsubscriber: pg_createsubscriber.o $(WIN32RES) | submake-libpq submake-libpgport submake-libpgfeutils
$(CC) $(CFLAGS) $^ $(LDFLAGS) $(LDFLAGS_EX) $(LIBS) -o $@$(X)
pg_receivewal: pg_receivewal.o $(OBJS) | submake-libpq submake-libpgport submake-libpgfeutils
$(CC) $(CFLAGS) pg_receivewal.o $(OBJS) $(LDFLAGS) $(LDFLAGS_EX) $(LIBS) -o $@$(X)
@ -57,6 +60,7 @@ pg_recvlogical: pg_recvlogical.o $(OBJS) | submake-libpq submake-libpgport subma
install: all installdirs
$(INSTALL_PROGRAM) pg_basebackup$(X) '$(DESTDIR)$(bindir)/pg_basebackup$(X)'
$(INSTALL_PROGRAM) pg_createsubscriber$(X) '$(DESTDIR)$(bindir)/pg_createsubscriber$(X)'
$(INSTALL_PROGRAM) pg_receivewal$(X) '$(DESTDIR)$(bindir)/pg_receivewal$(X)'
$(INSTALL_PROGRAM) pg_recvlogical$(X) '$(DESTDIR)$(bindir)/pg_recvlogical$(X)'
@ -65,12 +69,13 @@ installdirs:
uninstall:
rm -f '$(DESTDIR)$(bindir)/pg_basebackup$(X)'
rm -f '$(DESTDIR)$(bindir)/pg_createsubscriber$(X)'
rm -f '$(DESTDIR)$(bindir)/pg_receivewal$(X)'
rm -f '$(DESTDIR)$(bindir)/pg_recvlogical$(X)'
clean distclean:
rm -f pg_basebackup$(X) pg_receivewal$(X) pg_recvlogical$(X) \
$(BBOBJS) pg_receivewal.o pg_recvlogical.o \
rm -f pg_basebackup$(X) pg_createsubscriber$(X) pg_receivewal$(X) pg_recvlogical$(X) \
$(BBOBJS) pg_createsubscriber.o pg_receivewal.o pg_recvlogical.o \
$(OBJS)
rm -rf tmp_check

View File

@ -38,6 +38,24 @@ pg_basebackup = executable('pg_basebackup',
bin_targets += pg_basebackup
pg_createsubscriber_sources = files(
'pg_createsubscriber.c'
)
if host_system == 'windows'
pg_createsubscriber_sources += rc_bin_gen.process(win32ver_rc, extra_args: [
'--NAME', 'pg_createsubscriber',
'--FILEDESC', 'pg_createsubscriber - create a new logical replica from a standby server',])
endif
pg_createsubscriber = executable('pg_createsubscriber',
pg_createsubscriber_sources,
dependencies: [frontend_code, libpq],
kwargs: default_bin_args,
)
bin_targets += pg_createsubscriber
pg_receivewal_sources = files(
'pg_receivewal.c',
)
@ -89,6 +107,7 @@ tests += {
't/011_in_place_tablespace.pl',
't/020_pg_receivewal.pl',
't/030_pg_recvlogical.pl',
't/040_pg_createsubscriber.pl',
],
},
}

View File

@ -8,6 +8,7 @@ GETTEXT_FILES = $(FRONTEND_COMMON_GETTEXT_FILES) \
bbstreamer_tar.c \
bbstreamer_zstd.c \
pg_basebackup.c \
pg_createsubscriber.c \
pg_receivewal.c \
pg_recvlogical.c \
receivelog.c \

File diff suppressed because it is too large Load Diff

View File

@ -0,0 +1,364 @@
# Copyright (c) 2024, PostgreSQL Global Development Group
#
# Test using a standby server as the subscriber.
use strict;
use warnings FATAL => 'all';
use PostgreSQL::Test::Cluster;
use PostgreSQL::Test::Utils;
use Test::More;
program_help_ok('pg_createsubscriber');
program_version_ok('pg_createsubscriber');
program_options_handling_ok('pg_createsubscriber');
my $datadir = PostgreSQL::Test::Utils::tempdir;
#
# Test mandatory options
command_fails(['pg_createsubscriber'],
'no subscriber data directory specified');
command_fails(
[ 'pg_createsubscriber', '--pgdata', $datadir ],
'no publisher connection string specified');
command_fails(
[
'pg_createsubscriber', '--verbose',
'--pgdata', $datadir,
'--publisher-server', 'port=5432'
],
'no database name specified');
command_fails(
[
'pg_createsubscriber', '--verbose',
'--pgdata', $datadir,
'--publisher-server', 'port=5432',
'--database', 'pg1',
'--database', 'pg1'
],
'duplicate database name');
command_fails(
[
'pg_createsubscriber', '--verbose',
'--pgdata', $datadir,
'--publisher-server', 'port=5432',
'--publication', 'foo1',
'--publication', 'foo1',
'--database', 'pg1',
'--database', 'pg2'
],
'duplicate publication name');
command_fails(
[
'pg_createsubscriber', '--verbose',
'--pgdata', $datadir,
'--publisher-server', 'port=5432',
'--publication', 'foo1',
'--database', 'pg1',
'--database', 'pg2'
],
'wrong number of publication names');
command_fails(
[
'pg_createsubscriber', '--verbose',
'--pgdata', $datadir,
'--publisher-server', 'port=5432',
'--publication', 'foo1',
'--publication', 'foo2',
'--subscription', 'bar1',
'--database', 'pg1',
'--database', 'pg2'
],
'wrong number of subscription names');
command_fails(
[
'pg_createsubscriber', '--verbose',
'--pgdata', $datadir,
'--publisher-server', 'port=5432',
'--publication', 'foo1',
'--publication', 'foo2',
'--subscription', 'bar1',
'--subscription', 'bar2',
'--replication-slot', 'baz1',
'--database', 'pg1',
'--database', 'pg2'
],
'wrong number of replication slot names');
# Set up node P as primary
my $node_p = PostgreSQL::Test::Cluster->new('node_p');
$node_p->init(allows_streaming => 'logical');
$node_p->start;
# Set up node F as about-to-fail node
# Force it to initialize a new cluster instead of copying a
# previously initdb'd cluster. New cluster has a different system identifier so
# we can test if the target cluster is a copy of the source cluster.
my $node_f = PostgreSQL::Test::Cluster->new('node_f');
$node_f->init(force_initdb => 1, allows_streaming => 'logical');
# On node P
# - create databases
# - create test tables
# - insert a row
# - create a physical replication slot
$node_p->safe_psql(
'postgres', q(
CREATE DATABASE pg1;
CREATE DATABASE pg2;
));
$node_p->safe_psql('pg1', 'CREATE TABLE tbl1 (a text)');
$node_p->safe_psql('pg1', "INSERT INTO tbl1 VALUES('first row')");
$node_p->safe_psql('pg2', 'CREATE TABLE tbl2 (a text)');
my $slotname = 'physical_slot';
$node_p->safe_psql('pg2',
"SELECT pg_create_physical_replication_slot('$slotname')");
# Set up node S as standby linking to node P
$node_p->backup('backup_1');
my $node_s = PostgreSQL::Test::Cluster->new('node_s');
$node_s->init_from_backup($node_p, 'backup_1', has_streaming => 1);
$node_s->append_conf(
'postgresql.conf', qq[
primary_slot_name = '$slotname'
]);
$node_s->set_standby_mode();
$node_s->start;
# Set up node T as standby linking to node P then promote it
my $node_t = PostgreSQL::Test::Cluster->new('node_t');
$node_t->init_from_backup($node_p, 'backup_1', has_streaming => 1);
$node_t->set_standby_mode();
$node_t->start;
$node_t->promote;
$node_t->stop;
# Run pg_createsubscriber on a promoted server
command_fails(
[
'pg_createsubscriber', '--verbose',
'--dry-run', '--pgdata',
$node_t->data_dir, '--publisher-server',
$node_p->connstr('pg1'),
'--socket-directory', $node_t->host,
'--subscriber-port', $node_t->port,
'--database', 'pg1',
'--database', 'pg2'
],
'target server is not in recovery');
# Run pg_createsubscriber when standby is running
command_fails(
[
'pg_createsubscriber', '--verbose',
'--dry-run', '--pgdata',
$node_s->data_dir, '--publisher-server',
$node_p->connstr('pg1'),
'--socket-directory', $node_s->host,
'--subscriber-port', $node_s->port,
'--database', 'pg1',
'--database', 'pg2'
],
'standby is up and running');
# Run pg_createsubscriber on about-to-fail node F
command_fails(
[
'pg_createsubscriber', '--verbose',
'--pgdata', $node_f->data_dir,
'--publisher-server', $node_p->connstr('pg1'),
'--socket-directory', $node_f->host,
'--subscriber-port', $node_f->port,
'--database', 'pg1',
'--database', 'pg2'
],
'subscriber data directory is not a copy of the source database cluster');
# Set up node C as standby linking to node S
$node_s->backup('backup_2');
my $node_c = PostgreSQL::Test::Cluster->new('node_c');
$node_c->init_from_backup($node_s, 'backup_2', has_streaming => 1);
$node_c->adjust_conf('postgresql.conf', 'primary_slot_name', undef);
$node_c->set_standby_mode();
# Run pg_createsubscriber on node C (P -> S -> C)
command_fails(
[
'pg_createsubscriber', '--verbose',
'--dry-run', '--pgdata',
$node_c->data_dir, '--publisher-server',
$node_s->connstr('pg1'),
'--socket-directory', $node_c->host,
'--subscriber-port', $node_c->port,
'--database', 'pg1',
'--database', 'pg2'
],
'primary server is in recovery');
# Insert another row on node P and wait node S to catch up
$node_p->safe_psql('pg1', "INSERT INTO tbl1 VALUES('second row')");
$node_p->wait_for_replay_catchup($node_s);
# Check some unmet conditions on node P
$node_p->append_conf('postgresql.conf', q{
wal_level = replica
max_replication_slots = 1
max_wal_senders = 1
max_worker_processes = 2
});
$node_p->restart;
$node_s->stop;
command_fails(
[
'pg_createsubscriber', '--verbose',
'--dry-run', '--pgdata',
$node_s->data_dir, '--publisher-server',
$node_p->connstr('pg1'),
'--socket-directory', $node_s->host,
'--subscriber-port', $node_s->port,
'--database', 'pg1',
'--database', 'pg2'
],
'primary contains unmet conditions on node P');
# Restore default settings here but only apply it after testing standby. Some
# standby settings should not be a lower setting than on the primary.
$node_p->append_conf('postgresql.conf', q{
wal_level = logical
max_replication_slots = 10
max_wal_senders = 10
max_worker_processes = 8
});
# Check some unmet conditions on node S
$node_s->append_conf('postgresql.conf', q{
max_replication_slots = 1
max_logical_replication_workers = 1
max_worker_processes = 2
});
command_fails(
[
'pg_createsubscriber', '--verbose',
'--dry-run', '--pgdata',
$node_s->data_dir, '--publisher-server',
$node_p->connstr('pg1'),
'--socket-directory', $node_s->host,
'--subscriber-port', $node_s->port,
'--database', 'pg1',
'--database', 'pg2'
],
'standby contains unmet conditions on node S');
$node_s->append_conf('postgresql.conf', q{
max_replication_slots = 10
max_logical_replication_workers = 4
max_worker_processes = 8
});
# Restore default settings on both servers
$node_p->restart;
# dry run mode on node S
command_ok(
[
'pg_createsubscriber', '--verbose',
'--dry-run', '--pgdata',
$node_s->data_dir, '--publisher-server',
$node_p->connstr('pg1'),
'--socket-directory', $node_s->host,
'--subscriber-port', $node_s->port,
'--publication', 'pub1',
'--publication', 'pub2',
'--subscription', 'sub1',
'--subscription', 'sub2',
'--database', 'pg1',
'--database', 'pg2'
],
'run pg_createsubscriber --dry-run on node S');
# Check if node S is still a standby
$node_s->start;
is($node_s->safe_psql('postgres', 'SELECT pg_catalog.pg_is_in_recovery()'),
't', 'standby is in recovery');
$node_s->stop;
# pg_createsubscriber can run without --databases option
command_ok(
[
'pg_createsubscriber', '--verbose',
'--dry-run', '--pgdata',
$node_s->data_dir, '--publisher-server',
$node_p->connstr('pg1'),
'--socket-directory', $node_s->host,
'--subscriber-port', $node_s->port,
'--replication-slot', 'replslot1'
],
'run pg_createsubscriber without --databases');
# Run pg_createsubscriber on node S
command_ok(
[
'pg_createsubscriber', '--verbose',
'--verbose', '--pgdata',
$node_s->data_dir, '--publisher-server',
$node_p->connstr('pg1'),
'--socket-directory', $node_s->host,
'--subscriber-port', $node_s->port,
'--publication', 'pub1',
'--publication', 'Pub2',
'--replication-slot', 'replslot1',
'--replication-slot', 'replslot2',
'--database', 'pg1',
'--database', 'pg2'
],
'run pg_createsubscriber on node S');
# Confirm the physical replication slot has been removed
my $result = $node_p->safe_psql('pg1',
"SELECT count(*) FROM pg_replication_slots WHERE slot_name = '$slotname'"
);
is($result, qq(0),
'the physical replication slot used as primary_slot_name has been removed'
);
# Insert rows on P
$node_p->safe_psql('pg1', "INSERT INTO tbl1 VALUES('third row')");
$node_p->safe_psql('pg2', "INSERT INTO tbl2 VALUES('row 1')");
# Start subscriber
$node_s->start;
# Get subscription names
$result = $node_s->safe_psql(
'postgres', qq(
SELECT subname FROM pg_subscription WHERE subname ~ '^pg_createsubscriber_'
));
my @subnames = split("\n", $result);
# Wait subscriber to catch up
$node_s->wait_for_subscription_sync($node_p, $subnames[0]);
$node_s->wait_for_subscription_sync($node_p, $subnames[1]);
# Check result on database pg1
$result = $node_s->safe_psql('pg1', 'SELECT * FROM tbl1');
is( $result, qq(first row
second row
third row),
'logical replication works on database pg1');
# Check result on database pg2
$result = $node_s->safe_psql('pg2', 'SELECT * FROM tbl2');
is($result, qq(row 1), 'logical replication works on database pg2');
# Different system identifier?
my $sysid_p = $node_p->safe_psql('postgres',
'SELECT system_identifier FROM pg_control_system()');
my $sysid_s = $node_s->safe_psql('postgres',
'SELECT system_identifier FROM pg_control_system()');
ok($sysid_p != $sysid_s, 'system identifier was changed');
# clean up
$node_p->teardown_node;
$node_s->teardown_node;
$node_t->teardown_node;
$node_f->teardown_node;
done_testing();