1 <!-- doc/src/sgml/logical-replication.sgml -->
3 <chapter id=
"logical-replication">
4 <title>Logical Replication
</title>
7 Logical replication is a method of replicating data objects and their
8 changes, based upon their replication identity (usually a primary key). We
9 use the term logical in contrast to physical replication, which uses exact
10 block addresses and byte-by-byte replication. PostgreSQL supports both
11 mechanisms concurrently, see
<xref linkend=
"high-availability"/>. Logical
12 replication allows fine-grained control over both data replication and
17 Logical replication uses a
<firstterm>publish
</firstterm>
18 and
<firstterm>subscribe
</firstterm> model with one or
19 more
<firstterm>subscribers
</firstterm> subscribing to one or more
20 <firstterm>publications
</firstterm> on a
<firstterm>publisher
</firstterm>
21 node. Subscribers pull data from the publications they subscribe to and may
22 subsequently re-publish data to allow cascading replication or more complex
27 Logical replication of a table typically starts with taking a snapshot
28 of the data on the publisher database and copying that to the subscriber.
29 Once that is done, the changes on the publisher are sent to the subscriber
30 as they occur in real-time. The subscriber applies the data in the same
31 order as the publisher so that transactional consistency is guaranteed for
32 publications within a single subscription. This method of data replication
33 is sometimes referred to as transactional replication.
37 The typical use-cases for logical replication are:
42 Sending incremental changes in a single database or a subset of a
43 database to subscribers as they occur.
49 Firing triggers for individual changes as they arrive on the
56 Consolidating multiple databases into a single one (for example for
63 Replicating between different major versions of PostgreSQL.
69 Replicating between PostgreSQL instances on different platforms (for
70 example Linux to Windows)
76 Giving access to replicated data to different groups of users.
82 Sharing a subset of the database between multiple databases.
89 The subscriber database behaves in the same way as any other PostgreSQL
90 instance and can be used as a publisher for other databases by defining its
91 own publications. When the subscriber is treated as read-only by
92 application, there will be no conflicts from a single subscription. On the
93 other hand, if there are other writes done either by an application or by other
94 subscribers to the same set of tables, conflicts can arise.
97 <sect1 id=
"logical-replication-publication">
98 <title>Publication
</title>
101 A
<firstterm>publication
</firstterm> can be defined on any physical
102 replication primary. The node where a publication is defined is referred to
103 as
<firstterm>publisher
</firstterm>. A publication is a set of changes
104 generated from a table or a group of tables, and might also be described as
105 a change set or replication set. Each publication exists in only one database.
109 Publications are different from schemas and do not affect how the table is
110 accessed. Each table can be added to multiple publications if needed.
111 Publications may currently only contain tables and all tables in schema.
112 Objects must be added explicitly, except when a publication is created for
113 <literal>ALL TABLES
</literal>.
117 Publications can choose to limit the changes they produce to
118 any combination of
<command>INSERT
</command>,
<command>UPDATE
</command>,
119 <command>DELETE
</command>, and
<command>TRUNCATE
</command>, similar to how triggers are fired by
120 particular event types. By default, all operation types are replicated.
121 These publication specifications apply only for DML operations; they do not affect the initial
122 data synchronization copy. (Row filters have no effect for
123 <command>TRUNCATE
</command>. See
<xref linkend=
"logical-replication-row-filter"/>).
127 A published table must have a
<firstterm>replica identity
</firstterm> configured in
128 order to be able to replicate
<command>UPDATE
</command>
129 and
<command>DELETE
</command> operations, so that appropriate rows to
130 update or delete can be identified on the subscriber side. By default,
131 this is the primary key, if there is one. Another unique index (with
132 certain additional requirements) can also be set to be the replica
133 identity. If the table does not have any suitable key, then it can be set
134 to replica identity
<literal>FULL
</literal>, which means the entire row becomes
135 the key. When replica identity
<literal>FULL
</literal> is specified,
136 indexes can be used on the subscriber side for searching the rows. Candidate
137 indexes must be btree or hash, non-partial, and the leftmost index field must
138 be a column (not an expression) that references the published table column.
139 These restrictions on the non-unique index properties adhere to some of the
140 restrictions that are enforced for primary keys. If there are no such
141 suitable indexes, the search on the subscriber side can be very inefficient,
142 therefore replica identity
<literal>FULL
</literal> should only be used as a
143 fallback if no other solution is possible. If a replica identity other
144 than
<literal>FULL
</literal> is set on the publisher side, a replica identity
145 comprising the same or fewer columns must also be set on the subscriber
146 side. See
<xref linkend=
"sql-altertable-replica-identity"/> for details on
147 how to set the replica identity. If a table without a replica identity is
148 added to a publication that replicates
<command>UPDATE
</command>
149 or
<command>DELETE
</command> operations then
150 subsequent
<command>UPDATE
</command> or
<command>DELETE
</command>
151 operations will cause an error on the publisher.
<command>INSERT
</command>
152 operations can proceed regardless of any replica identity.
156 Every publication can have multiple subscribers.
160 A publication is created using the
<link linkend=
"sql-createpublication"><command>CREATE PUBLICATION
</command></link>
161 command and may later be altered or dropped using corresponding commands.
165 The individual tables can be added and removed dynamically using
166 <link linkend=
"sql-alterpublication"><command>ALTER PUBLICATION
</command></link>. Both the
<literal>ADD
167 TABLE
</literal> and
<literal>DROP TABLE
</literal> operations are
168 transactional; so the table will start or stop replicating at the correct
169 snapshot once the transaction has committed.
173 <sect1 id=
"logical-replication-subscription">
174 <title>Subscription
</title>
177 A
<firstterm>subscription
</firstterm> is the downstream side of logical
178 replication. The node where a subscription is defined is referred to as
179 the
<firstterm>subscriber
</firstterm>. A subscription defines the connection
180 to another database and set of publications (one or more) to which it wants
185 The subscriber database behaves in the same way as any other PostgreSQL
186 instance and can be used as a publisher for other databases by defining its
191 A subscriber node may have multiple subscriptions if desired. It is
192 possible to define multiple subscriptions between a single
193 publisher-subscriber pair, in which case care must be taken to ensure
194 that the subscribed publication objects don't overlap.
198 Each subscription will receive changes via one replication slot (see
199 <xref linkend=
"streaming-replication-slots"/>). Additional replication
200 slots may be required for the initial data synchronization of
201 pre-existing table data and those will be dropped at the end of data
206 A logical replication subscription can be a standby for synchronous
207 replication (see
<xref linkend=
"synchronous-replication"/>). The standby
208 name is by default the subscription name. An alternative name can be
209 specified as
<literal>application_name
</literal> in the connection
210 information of the subscription.
214 Subscriptions are dumped by
<command>pg_dump
</command> if the current user
215 is a superuser. Otherwise a warning is written and subscriptions are
216 skipped, because non-superusers cannot read all subscription information
217 from the
<structname>pg_subscription
</structname> catalog.
221 The subscription is added using
<link linkend=
"sql-createsubscription"><command>CREATE SUBSCRIPTION
</command></link> and
222 can be stopped/resumed at any time using the
223 <link linkend=
"sql-altersubscription"><command>ALTER SUBSCRIPTION
</command></link> command and removed using
224 <link linkend=
"sql-dropsubscription"><command>DROP SUBSCRIPTION
</command></link>.
228 When a subscription is dropped and recreated, the synchronization
229 information is lost. This means that the data has to be resynchronized
234 The schema definitions are not replicated, and the published tables must
235 exist on the subscriber. Only regular tables may be
236 the target of replication. For example, you can't replicate to a view.
240 The tables are matched between the publisher and the subscriber using the
241 fully qualified table name. Replication to differently-named tables on the
242 subscriber is not supported.
246 Columns of a table are also matched by name. The order of columns in the
247 subscriber table does not need to match that of the publisher. The data
248 types of the columns do not need to match, as long as the text
249 representation of the data can be converted to the target type. For
250 example, you can replicate from a column of type
<type>integer
</type> to a
251 column of type
<type>bigint
</type>. The target table can also have
252 additional columns not provided by the published table. Any such columns
253 will be filled with the default value as specified in the definition of the
254 target table. However, logical replication in binary format is more
256 <link linkend=
"sql-createsubscription-params-with-binary"><literal>binary
</literal></link>
257 option of
<command>CREATE SUBSCRIPTION
</command> for details.
260 <sect2 id=
"logical-replication-subscription-slot">
261 <title>Replication Slot Management
</title>
264 As mentioned earlier, each (active) subscription receives changes from a
265 replication slot on the remote (publishing) side.
268 Additional table synchronization slots are normally transient, created
269 internally to perform initial table synchronization and dropped
270 automatically when they are no longer needed. These table synchronization
271 slots have generated names:
<quote><literal>pg_%u_sync_%u_%llu
</literal></quote>
272 (parameters: Subscription
<parameter>oid
</parameter>,
273 Table
<parameter>relid
</parameter>, system identifier
<parameter>sysid
</parameter>)
276 Normally, the remote replication slot is created automatically when the
277 subscription is created using
<link linkend=
"sql-createsubscription">
278 <command>CREATE SUBSCRIPTION
</command></link> and it
279 is dropped automatically when the subscription is dropped using
280 <link linkend=
"sql-dropsubscription"><command>DROP SUBSCRIPTION
</command></link>.
281 In some situations, however, it can
282 be useful or necessary to manipulate the subscription and the underlying
283 replication slot separately. Here are some scenarios:
288 When creating a subscription, the replication slot already exists. In
289 that case, the subscription can be created using
290 the
<literal>create_slot = false
</literal> option to associate with the
297 When creating a subscription, the remote host is not reachable or in an
298 unclear state. In that case, the subscription can be created using
299 the
<literal>connect = false
</literal> option. The remote host will then not
300 be contacted at all. This is what
<application>pg_dump
</application>
301 uses. The remote replication slot will then have to be created
302 manually before the subscription can be activated.
308 When dropping a subscription, the replication slot should be kept.
309 This could be useful when the subscriber database is being moved to a
310 different host and will be activated from there. In that case,
311 disassociate the slot from the subscription using
312 <link linkend=
"sql-altersubscription"><command>ALTER SUBSCRIPTION
</command></link>
313 before attempting to drop the subscription.
319 When dropping a subscription, the remote host is not reachable. In
320 that case, disassociate the slot from the subscription
321 using
<command>ALTER SUBSCRIPTION
</command> before attempting to drop
322 the subscription. If the remote database instance no longer exists, no
323 further action is then necessary. If, however, the remote database
324 instance is just unreachable, the replication slot (and any still
325 remaining table synchronization slots) should then be
326 dropped manually; otherwise it/they would continue to reserve WAL and might
327 eventually cause the disk to fill up. Such cases should be carefully
335 <sect2 id=
"logical-replication-subscription-examples">
336 <title>Examples: Set Up Logical Replication
</title>
339 Create some test tables on the publisher.
341 test_pub=# CREATE TABLE t1(a int, b text, PRIMARY KEY(a));
343 test_pub=# CREATE TABLE t2(c int, d text, PRIMARY KEY(c));
345 test_pub=# CREATE TABLE t3(e int, f text, PRIMARY KEY(e));
347 </programlisting></para>
350 Create the same tables on the subscriber.
352 test_sub=# CREATE TABLE t1(a int, b text, PRIMARY KEY(a));
354 test_sub=# CREATE TABLE t2(c int, d text, PRIMARY KEY(c));
356 test_sub=# CREATE TABLE t3(e int, f text, PRIMARY KEY(e));
358 </programlisting></para>
361 Insert data to the tables at the publisher side.
363 test_pub=# INSERT INTO t1 VALUES (
1, 'one'), (
2, 'two'), (
3, 'three');
365 test_pub=# INSERT INTO t2 VALUES (
1, 'A'), (
2, 'B'), (
3, 'C');
367 test_pub=# INSERT INTO t3 VALUES (
1, 'i'), (
2, 'ii'), (
3, 'iii');
369 </programlisting></para>
372 Create publications for the tables. The publications
<literal>pub2
</literal>
373 and
<literal>pub3a
</literal> disallow some
374 <link linkend=
"sql-createpublication-params-with-publish"><literal>publish
</literal></link>
375 operations. The publication
<literal>pub3b
</literal> has a row filter (see
376 <xref linkend=
"logical-replication-row-filter"/>).
378 test_pub=# CREATE PUBLICATION pub1 FOR TABLE t1;
380 test_pub=# CREATE PUBLICATION pub2 FOR TABLE t2 WITH (publish = 'truncate');
382 test_pub=# CREATE PUBLICATION pub3a FOR TABLE t3 WITH (publish = 'truncate');
384 test_pub=# CREATE PUBLICATION pub3b FOR TABLE t3 WHERE (e
> 5);
386 </programlisting></para>
389 Create subscriptions for the publications. The subscription
390 <literal>sub3
</literal> subscribes to both
<literal>pub3a
</literal> and
391 <literal>pub3b
</literal>. All subscriptions will copy initial data by default.
393 test_sub=# CREATE SUBSCRIPTION sub1
394 test_sub-# CONNECTION 'host=localhost dbname=test_pub application_name=sub1'
395 test_sub-# PUBLICATION pub1;
397 test_sub=# CREATE SUBSCRIPTION sub2
398 test_sub-# CONNECTION 'host=localhost dbname=test_pub application_name=sub2'
399 test_sub-# PUBLICATION pub2;
401 test_sub=# CREATE SUBSCRIPTION sub3
402 test_sub-# CONNECTION 'host=localhost dbname=test_pub application_name=sub3'
403 test_sub-# PUBLICATION pub3a, pub3b;
405 </programlisting></para>
408 Observe that initial table data is copied, regardless of the
409 <literal>publish
</literal> operation of the publication.
411 test_sub=# SELECT * FROM t1;
419 test_sub=# SELECT * FROM t2;
426 </programlisting></para>
429 Furthermore, because the initial data copy ignores the
<literal>publish
</literal>
430 operation, and because publication
<literal>pub3a
</literal> has no row filter,
431 it means the copied table
<literal>t3
</literal> contains all rows even when
432 they do not match the row filter of publication
<literal>pub3b
</literal>.
434 test_sub=# SELECT * FROM t3;
441 </programlisting></para>
444 Insert more data to the tables at the publisher side.
446 test_pub=# INSERT INTO t1 VALUES (
4, 'four'), (
5, 'five'), (
6, 'six');
448 test_pub=# INSERT INTO t2 VALUES (
4, 'D'), (
5, 'E'), (
6, 'F');
450 test_pub=# INSERT INTO t3 VALUES (
4, 'iv'), (
5, 'v'), (
6, 'vi');
452 </programlisting></para>
455 Now the publisher side data looks like:
457 test_pub=# SELECT * FROM t1;
468 test_pub=# SELECT * FROM t2;
479 test_pub=# SELECT * FROM t3;
489 </programlisting></para>
492 Observe that during normal replication the appropriate
493 <literal>publish
</literal> operations are used. This means publications
494 <literal>pub2
</literal> and
<literal>pub3a
</literal> will not replicate the
495 <literal>INSERT
</literal>. Also, publication
<literal>pub3b
</literal> will
496 only replicate data that matches the row filter of
<literal>pub3b
</literal>.
497 Now the subscriber side data looks like:
499 test_sub=# SELECT * FROM t1;
510 test_sub=# SELECT * FROM t2;
518 test_sub=# SELECT * FROM t3;
526 </programlisting></para>
529 <sect2 id=
"logical-replication-subscription-examples-deferred-slot">
530 <title>Examples: Deferred Replication Slot Creation
</title>
533 There are some cases (e.g.
534 <xref linkend=
"logical-replication-subscription-slot"/>) where, if the
535 remote replication slot was not created automatically, the user must create
536 it manually before the subscription can be activated. The steps to create
537 the slot and activate the subscription are shown in the following examples.
538 These examples specify the standard logical decoding output plugin
539 (
<literal>pgoutput
</literal>), which is what the built-in logical
543 First, create a publication for the examples to use.
545 test_pub=# CREATE PUBLICATION pub1 FOR ALL TABLES;
547 </programlisting></para>
549 Example
1: Where the subscription says
<literal>connect = false
</literal>
555 Create the subscription.
557 test_sub=# CREATE SUBSCRIPTION sub1
558 test_sub-# CONNECTION 'host=localhost dbname=test_pub'
559 test_sub-# PUBLICATION pub1
560 test_sub-# WITH (connect=false);
561 WARNING: subscription was created, but is not connected
562 HINT: To initiate replication, you must manually create the replication slot, enable the subscription, and refresh the subscription.
564 </programlisting></para>
568 On the publisher, manually create a slot. Because the name was not
569 specified during
<literal>CREATE SUBSCRIPTION
</literal>, the name of the
570 slot to create is same as the subscription name, e.g.
"sub1".
572 test_pub=# SELECT * FROM pg_create_logical_replication_slot('sub1', 'pgoutput');
574 -----------+-----------
577 </programlisting></para>
581 On the subscriber, complete the activation of the subscription. After
582 this the tables of
<literal>pub1
</literal> will start replicating.
584 test_sub=# ALTER SUBSCRIPTION sub1 ENABLE;
586 test_sub=# ALTER SUBSCRIPTION sub1 REFRESH PUBLICATION;
588 </programlisting></para>
594 Example
2: Where the subscription says
<literal>connect = false
</literal>,
595 but also specifies the
596 <link linkend=
"sql-createsubscription-params-with-slot-name"><literal>slot_name
</literal></link>
601 Create the subscription.
603 test_sub=# CREATE SUBSCRIPTION sub1
604 test_sub-# CONNECTION 'host=localhost dbname=test_pub'
605 test_sub-# PUBLICATION pub1
606 test_sub-# WITH (connect=false, slot_name='myslot');
607 WARNING: subscription was created, but is not connected
608 HINT: To initiate replication, you must manually create the replication slot, enable the subscription, and refresh the subscription.
610 </programlisting></para>
614 On the publisher, manually create a slot using the same name that was
615 specified during
<literal>CREATE SUBSCRIPTION
</literal>, e.g.
"myslot".
617 test_pub=# SELECT * FROM pg_create_logical_replication_slot('myslot', 'pgoutput');
619 -----------+-----------
622 </programlisting></para>
626 On the subscriber, the remaining subscription activation steps are the
629 test_sub=# ALTER SUBSCRIPTION sub1 ENABLE;
631 test_sub=# ALTER SUBSCRIPTION sub1 REFRESH PUBLICATION;
633 </programlisting></para>
639 Example
3: Where the subscription specifies
<literal>slot_name = NONE
</literal>
643 Create the subscription. When
<literal>slot_name = NONE
</literal> then
644 <literal>enabled = false
</literal>, and
645 <literal>create_slot = false
</literal> are also needed.
647 test_sub=# CREATE SUBSCRIPTION sub1
648 test_sub-# CONNECTION 'host=localhost dbname=test_pub'
649 test_sub-# PUBLICATION pub1
650 test_sub-# WITH (slot_name=NONE, enabled=false, create_slot=false);
652 </programlisting></para>
656 On the publisher, manually create a slot using any name, e.g.
"myslot".
658 test_pub=# SELECT * FROM pg_create_logical_replication_slot('myslot', 'pgoutput');
660 -----------+-----------
663 </programlisting></para>
667 On the subscriber, associate the subscription with the slot name just
670 test_sub=# ALTER SUBSCRIPTION sub1 SET (slot_name='myslot');
672 </programlisting></para>
676 The remaining subscription activation steps are same as before.
678 test_sub=# ALTER SUBSCRIPTION sub1 ENABLE;
680 test_sub=# ALTER SUBSCRIPTION sub1 REFRESH PUBLICATION;
682 </programlisting></para>
690 <sect1 id=
"logical-replication-failover">
691 <title>Logical Replication Failover
</title>
694 To allow subscriber nodes to continue replicating data from the publisher
695 node even when the publisher node goes down, there must be a physical standby
696 corresponding to the publisher node. The logical slots on the primary server
697 corresponding to the subscriptions can be synchronized to the standby server by
698 specifying
<literal>failover = true
</literal> when creating subscriptions. See
699 <xref linkend=
"logicaldecoding-replication-slots-synchronization"/> for details.
701 <link linkend=
"sql-createsubscription-params-with-failover"><literal>failover
</literal></link>
702 parameter ensures a seamless transition of those subscriptions after the
703 standby is promoted. They can continue subscribing to publications on the
708 Because the slot synchronization logic copies asynchronously, it is
709 necessary to confirm that replication slots have been synced to the standby
710 server before the failover happens. To ensure a successful failover, the
711 standby server must be ahead of the subscriber. This can be achieved by
713 <link linkend=
"guc-synchronized-standby-slots"><varname>synchronized_standby_slots
</varname></link>.
717 To confirm that the standby server is indeed ready for failover, follow these
718 steps to verify that all necessary logical replication slots have been
719 synchronized to the standby server:
723 <step performance=
"required">
725 On the subscriber node, use the following SQL to identify which replication
726 slots should be synced to the standby that we plan to promote. This query
727 will return the relevant replication slots associated with the
728 failover-enabled subscriptions.
731 array_agg(quote_literal(s.subslotname)) AS slots
732 FROM pg_subscription s
733 WHERE s.subfailover AND
734 s.subslotname IS NOT NULL;
737 {'sub1','sub2','sub3'}
739 </programlisting></para>
741 <step performance=
"required">
743 On the subscriber node, use the following SQL to identify which table
744 synchronization slots should be synced to the standby that we plan to promote.
745 This query needs to be run on each database that includes the failover-enabled
746 subscription(s). Note that the table sync slot should be synced to the standby
747 server only if the table copy is finished
748 (See
<xref linkend=
"catalog-pg-subscription-rel"/>).
749 We don't need to ensure that the table sync slots are synced in other scenarios
750 as they will either be dropped or re-created on the new primary server in those
754 array_agg(quote_literal(slot_name)) AS slots
757 SELECT CONCAT('pg_', srsubid, '_sync_', srrelid, '_', ctl.system_identifier) AS slot_name
758 FROM pg_control_system() ctl, pg_subscription_rel r, pg_subscription s
759 WHERE r.srsubstate = 'f' AND s.oid = r.srsubid AND s.subfailover
763 {'pg_16394_sync_16385_7394666715149055164'}
765 </programlisting></para>
767 <step performance=
"required">
769 Check that the logical replication slots identified above exist on
770 the standby server and are ready for failover.
772 test_standby=# SELECT slot_name, (synced AND NOT temporary AND NOT conflicting) AS failover_ready
773 FROM pg_replication_slots
775 ('sub1','sub2','sub3', 'pg_16394_sync_16385_7394666715149055164');
776 slot_name | failover_ready
777 --------------------------------------------+----------------
781 pg_16394_sync_16385_7394666715149055164 | t
783 </programlisting></para>
788 If all the slots are present on the standby server and the result
789 (
<literal>failover_ready
</literal>) of the above SQL query is true, then
790 existing subscriptions can continue subscribing to publications now on the
796 <sect1 id=
"logical-replication-row-filter">
797 <title>Row Filters
</title>
800 By default, all data from all published tables will be replicated to the
801 appropriate subscribers. The replicated data can be reduced by using a
802 <firstterm>row filter
</firstterm>. A user might choose to use row filters
803 for behavioral, security or performance reasons. If a published table sets a
804 row filter, a row is replicated only if its data satisfies the row filter
805 expression. This allows a set of tables to be partially replicated. The row
806 filter is defined per table. Use a
<literal>WHERE
</literal> clause after the
807 table name for each published table that requires data to be filtered out.
808 The
<literal>WHERE
</literal> clause must be enclosed by parentheses. See
809 <xref linkend=
"sql-createpublication"/> for details.
812 <sect2 id=
"logical-replication-row-filter-rules">
813 <title>Row Filter Rules
</title>
816 Row filters are applied
<emphasis>before
</emphasis> publishing the changes.
817 If the row filter evaluates to
<literal>false
</literal> or
<literal>NULL
</literal>
818 then the row is not replicated. The
<literal>WHERE
</literal> clause expression
819 is evaluated with the same role used for the replication connection (i.e.
820 the role specified in the
821 <link linkend=
"sql-createsubscription-params-connection"><literal>CONNECTION
</literal></link>
822 clause of the
<xref linkend=
"sql-createsubscription"/>). Row filters have
823 no effect for
<command>TRUNCATE
</command> command.
828 <sect2 id=
"logical-replication-row-filter-restrictions">
829 <title>Expression Restrictions
</title>
832 The
<literal>WHERE
</literal> clause allows only simple expressions. It
833 cannot contain user-defined functions, operators, types, and collations,
834 system column references or non-immutable built-in functions.
838 If a publication publishes
<command>UPDATE
</command> or
839 <command>DELETE
</command> operations, the row filter
<literal>WHERE
</literal>
840 clause must contain only columns that are covered by the replica identity
841 (see
<xref linkend=
"sql-altertable-replica-identity"/>). If a publication
842 publishes only
<command>INSERT
</command> operations, the row filter
843 <literal>WHERE
</literal> clause can use any column.
848 <sect2 id=
"logical-replication-row-filter-transformations">
849 <title>UPDATE Transformations
</title>
852 Whenever an
<command>UPDATE
</command> is processed, the row filter
853 expression is evaluated for both the old and new row (i.e. using the data
854 before and after the update). If both evaluations are
<literal>true
</literal>,
855 it replicates the
<command>UPDATE
</command> change. If both evaluations are
856 <literal>false
</literal>, it doesn't replicate the change. If only one of
857 the old/new rows matches the row filter expression, the
<command>UPDATE
</command>
858 is transformed to
<command>INSERT
</command> or
<command>DELETE
</command>, to
859 avoid any data inconsistency. The row on the subscriber should reflect what
860 is defined by the row filter expression on the publisher.
864 If the old row satisfies the row filter expression (it was sent to the
865 subscriber) but the new row doesn't, then, from a data consistency
866 perspective the old row should be removed from the subscriber.
867 So the
<command>UPDATE
</command> is transformed into a
<command>DELETE
</command>.
871 If the old row doesn't satisfy the row filter expression (it wasn't sent
872 to the subscriber) but the new row does, then, from a data consistency
873 perspective the new row should be added to the subscriber.
874 So the
<command>UPDATE
</command> is transformed into an
<command>INSERT
</command>.
878 <xref linkend=
"logical-replication-row-filter-transformations-summary"/>
879 summarizes the applied transformations.
882 <table id=
"logical-replication-row-filter-transformations-summary">
883 <title><command>UPDATE
</command> Transformation Summary
</title>
887 <entry>Old row
</entry><entry>New row
</entry><entry>Transformation
</entry>
892 <entry>no match
</entry><entry>no match
</entry><entry>don't replicate
</entry>
895 <entry>no match
</entry><entry>match
</entry><entry><literal>INSERT
</literal></entry>
898 <entry>match
</entry><entry>no match
</entry><entry><literal>DELETE
</literal></entry>
901 <entry>match
</entry><entry>match
</entry><entry><literal>UPDATE
</literal></entry>
909 <sect2 id=
"logical-replication-row-filter-partitioned-table">
910 <title>Partitioned Tables
</title>
913 If the publication contains a partitioned table, the publication parameter
914 <link linkend=
"sql-createpublication-params-with-publish-via-partition-root"><literal>publish_via_partition_root
</literal></link>
915 determines which row filter is used. If
<literal>publish_via_partition_root
</literal>
916 is
<literal>true
</literal>, the
<emphasis>root partitioned table's
</emphasis>
917 row filter is used. Otherwise, if
<literal>publish_via_partition_root
</literal>
918 is
<literal>false
</literal> (default), each
<emphasis>partition's
</emphasis>
924 <sect2 id=
"logical-replication-row-filter-initial-data-sync">
925 <title>Initial Data Synchronization
</title>
928 If the subscription requires copying pre-existing table data
929 and a publication contains
<literal>WHERE
</literal> clauses, only data that
930 satisfies the row filter expressions is copied to the subscriber.
934 If the subscription has several publications in which a table has been
935 published with different
<literal>WHERE
</literal> clauses, rows that satisfy
936 <emphasis>any
</emphasis> of the expressions will be copied. See
937 <xref linkend=
"logical-replication-row-filter-combining"/> for details.
942 Because initial data synchronization does not take into account the
943 <link linkend=
"sql-createpublication-params-with-publish"><literal>publish
</literal></link>
944 parameter when copying existing table data, some rows may be copied that
945 would not be replicated using DML. Refer to
946 <xref linkend=
"logical-replication-snapshot"/>, and see
947 <xref linkend=
"logical-replication-subscription-examples"/> for examples.
953 If the subscriber is in a release prior to
15, copy pre-existing data
954 doesn't use row filters even if they are defined in the publication.
955 This is because old releases can only copy the entire table data.
961 <sect2 id=
"logical-replication-row-filter-combining">
962 <title>Combining Multiple Row Filters
</title>
965 If the subscription has several publications in which the same table has
966 been published with different row filters (for the same
967 <link linkend=
"sql-createpublication-params-with-publish"><literal>publish
</literal></link>
968 operation), those expressions get ORed together, so that rows satisfying
969 <emphasis>any
</emphasis> of the expressions will be replicated. This means all
970 the other row filters for the same table become redundant if:
974 One of the publications has no row filter.
979 One of the publications was created using
980 <link linkend=
"sql-createpublication-params-for-all-tables"><literal>FOR ALL TABLES
</literal></link>.
981 This clause does not allow row filters.
986 One of the publications was created using
987 <link linkend=
"sql-createpublication-params-for-tables-in-schema"><literal>FOR TABLES IN SCHEMA
</literal></link>
988 and the table belongs to the referred schema. This clause does not allow
992 </itemizedlist></para>
996 <sect2 id=
"logical-replication-row-filter-examples">
997 <title>Examples
</title>
1000 Create some tables to be used in the following examples.
1002 test_pub=# CREATE TABLE t1(a int, b int, c text, PRIMARY KEY(a,c));
1004 test_pub=# CREATE TABLE t2(d int, e int, f int, PRIMARY KEY(d));
1006 test_pub=# CREATE TABLE t3(g int, h int, i int, PRIMARY KEY(g));
1008 </programlisting></para>
1011 Create some publications. Publication
<literal>p1
</literal> has one table
1012 (
<literal>t1
</literal>) and that table has a row filter. Publication
1013 <literal>p2
</literal> has two tables. Table
<literal>t1
</literal> has no row
1014 filter, and table
<literal>t2
</literal> has a row filter. Publication
1015 <literal>p3
</literal> has two tables, and both of them have a row filter.
1017 test_pub=# CREATE PUBLICATION p1 FOR TABLE t1 WHERE (a
> 5 AND c = 'NSW');
1019 test_pub=# CREATE PUBLICATION p2 FOR TABLE t1, t2 WHERE (e =
99);
1021 test_pub=# CREATE PUBLICATION p3 FOR TABLE t2 WHERE (d =
10), t3 WHERE (g =
10);
1023 </programlisting></para>
1026 <command>psql
</command> can be used to show the row filter expressions (if
1027 defined) for each publication.
1031 Owner | All tables | Inserts | Updates | Deletes | Truncates | Via root
1032 ----------+------------+---------+---------+---------+-----------+----------
1033 postgres | f | t | t | t | t | f
1035 "public.t1" WHERE ((a
> 5) AND (c = 'NSW'::text))
1038 Owner | All tables | Inserts | Updates | Deletes | Truncates | Via root
1039 ----------+------------+---------+---------+---------+-----------+----------
1040 postgres | f | t | t | t | t | f
1043 "public.t2" WHERE (e =
99)
1046 Owner | All tables | Inserts | Updates | Deletes | Truncates | Via root
1047 ----------+------------+---------+---------+---------+-----------+----------
1048 postgres | f | t | t | t | t | f
1050 "public.t2" WHERE (d =
10)
1051 "public.t3" WHERE (g =
10)
1052 </programlisting></para>
1055 <command>psql
</command> can be used to show the row filter expressions (if
1056 defined) for each table. See that table
<literal>t1
</literal> is a member
1057 of two publications, but has a row filter only in
<literal>p1
</literal>.
1058 See that table
<literal>t2
</literal> is a member of two publications, and
1059 has a different row filter in each of them.
1063 Column | Type | Collation | Nullable | Default
1064 --------+---------+-----------+----------+---------
1065 a | integer | | not null |
1067 c | text | | not null |
1069 "t1_pkey" PRIMARY KEY, btree (a, c)
1071 "p1" WHERE ((a
> 5) AND (c = 'NSW'::text))
1076 Column | Type | Collation | Nullable | Default
1077 --------+---------+-----------+----------+---------
1078 d | integer | | not null |
1082 "t2_pkey" PRIMARY KEY, btree (d)
1089 Column | Type | Collation | Nullable | Default
1090 --------+---------+-----------+----------+---------
1091 g | integer | | not null |
1095 "t3_pkey" PRIMARY KEY, btree (g)
1098 </programlisting></para>
1101 On the subscriber node, create a table
<literal>t1
</literal> with the same
1102 definition as the one on the publisher, and also create the subscription
1103 <literal>s1
</literal> that subscribes to the publication
<literal>p1
</literal>.
1105 test_sub=# CREATE TABLE t1(a int, b int, c text, PRIMARY KEY(a,c));
1107 test_sub=# CREATE SUBSCRIPTION s1
1108 test_sub-# CONNECTION 'host=localhost dbname=test_pub application_name=s1'
1109 test_sub-# PUBLICATION p1;
1111 </programlisting></para>
1114 Insert some rows. Only the rows satisfying the
<literal>t1 WHERE
</literal>
1115 clause of publication
<literal>p1
</literal> are replicated.
1117 test_pub=# INSERT INTO t1 VALUES (
2,
102, 'NSW');
1119 test_pub=# INSERT INTO t1 VALUES (
3,
103, 'QLD');
1121 test_pub=# INSERT INTO t1 VALUES (
4,
104, 'VIC');
1123 test_pub=# INSERT INTO t1 VALUES (
5,
105, 'ACT');
1125 test_pub=# INSERT INTO t1 VALUES (
6,
106, 'NSW');
1127 test_pub=# INSERT INTO t1 VALUES (
7,
107, 'NT');
1129 test_pub=# INSERT INTO t1 VALUES (
8,
108, 'QLD');
1131 test_pub=# INSERT INTO t1 VALUES (
9,
109, 'NSW');
1134 test_pub=# SELECT * FROM t1;
1148 test_sub=# SELECT * FROM t1;
1154 </programlisting></para>
1157 Update some data, where the old and new row values both
1158 satisfy the
<literal>t1 WHERE
</literal> clause of publication
1159 <literal>p1
</literal>. The
<command>UPDATE
</command> replicates
1160 the change as normal.
1162 test_pub=# UPDATE t1 SET b =
999 WHERE a =
6;
1165 test_pub=# SELECT * FROM t1;
1179 test_sub=# SELECT * FROM t1;
1185 </programlisting></para>
1188 Update some data, where the old row values did not satisfy
1189 the
<literal>t1 WHERE
</literal> clause of publication
<literal>p1
</literal>,
1190 but the new row values do satisfy it. The
<command>UPDATE
</command> is
1191 transformed into an
<command>INSERT
</command> and the change is replicated.
1192 See the new row on the subscriber.
1194 test_pub=# UPDATE t1 SET a =
555 WHERE a =
2;
1197 test_pub=# SELECT * FROM t1;
1211 test_sub=# SELECT * FROM t1;
1218 </programlisting></para>
1221 Update some data, where the old row values satisfied
1222 the
<literal>t1 WHERE
</literal> clause of publication
<literal>p1
</literal>,
1223 but the new row values do not satisfy it. The
<command>UPDATE
</command> is
1224 transformed into a
<command>DELETE
</command> and the change is replicated.
1225 See that the row is removed from the subscriber.
1227 test_pub=# UPDATE t1 SET c = 'VIC' WHERE a =
9;
1230 test_pub=# SELECT * FROM t1;
1244 test_sub=# SELECT * FROM t1;
1250 </programlisting></para>
1253 The following examples show how the publication parameter
1254 <link linkend=
"sql-createpublication-params-with-publish-via-partition-root"><literal>publish_via_partition_root
</literal></link>
1255 determines whether the row filter of the parent or child table will be used
1256 in the case of partitioned tables.
1260 Create a partitioned table on the publisher.
1262 test_pub=# CREATE TABLE parent(a int PRIMARY KEY) PARTITION BY RANGE(a);
1264 test_pub=# CREATE TABLE child PARTITION OF parent DEFAULT;
1267 Create the same tables on the subscriber.
1269 test_sub=# CREATE TABLE parent(a int PRIMARY KEY) PARTITION BY RANGE(a);
1271 test_sub=# CREATE TABLE child PARTITION OF parent DEFAULT;
1273 </programlisting></para>
1276 Create a publication
<literal>p4
</literal>, and then subscribe to it. The
1277 publication parameter
<literal>publish_via_partition_root
</literal> is set
1278 as true. There are row filters defined on both the partitioned table
1279 (
<literal>parent
</literal>), and on the partition (
<literal>child
</literal>).
1281 test_pub=# CREATE PUBLICATION p4 FOR TABLE parent WHERE (a
< 5), child WHERE (a
>=
5)
1282 test_pub-# WITH (publish_via_partition_root=true);
1286 test_sub=# CREATE SUBSCRIPTION s4
1287 test_sub-# CONNECTION 'host=localhost dbname=test_pub application_name=s4'
1288 test_sub-# PUBLICATION p4;
1290 </programlisting></para>
1293 Insert some values directly into the
<literal>parent
</literal> and
1294 <literal>child
</literal> tables. They replicate using the row filter of
1295 <literal>parent
</literal> (because
<literal>publish_via_partition_root
</literal>
1298 test_pub=# INSERT INTO parent VALUES (
2), (
4), (
6);
1300 test_pub=# INSERT INTO child VALUES (
3), (
5), (
7);
1303 test_pub=# SELECT * FROM parent ORDER BY a;
1315 test_sub=# SELECT * FROM parent ORDER BY a;
1322 </programlisting></para>
1325 Repeat the same test, but with a different value for
<literal>publish_via_partition_root
</literal>.
1326 The publication parameter
<literal>publish_via_partition_root
</literal> is
1327 set as false. A row filter is defined on the partition (
<literal>child
</literal>).
1329 test_pub=# DROP PUBLICATION p4;
1331 test_pub=# CREATE PUBLICATION p4 FOR TABLE parent, child WHERE (a
>=
5)
1332 test_pub-# WITH (publish_via_partition_root=false);
1336 test_sub=# ALTER SUBSCRIPTION s4 REFRESH PUBLICATION;
1338 </programlisting></para>
1341 Do the inserts on the publisher same as before. They replicate using the
1342 row filter of
<literal>child
</literal> (because
1343 <literal>publish_via_partition_root
</literal> is false).
1345 test_pub=# TRUNCATE parent;
1347 test_pub=# INSERT INTO parent VALUES (
2), (
4), (
6);
1349 test_pub=# INSERT INTO child VALUES (
3), (
5), (
7);
1352 test_pub=# SELECT * FROM parent ORDER BY a;
1364 test_sub=# SELECT * FROM child ORDER BY a;
1371 </programlisting></para>
1377 <sect1 id=
"logical-replication-col-lists">
1378 <title>Column Lists
</title>
1381 Each publication can optionally specify which columns of each table are
1382 replicated to subscribers. The table on the subscriber side must have at
1383 least all the columns that are published. If no column list is specified,
1384 then all columns on the publisher are replicated.
1385 See
<xref linkend=
"sql-createpublication"/> for details on the syntax.
1389 The choice of columns can be based on behavioral or performance reasons.
1390 However, do not rely on this feature for security: a malicious subscriber
1391 is able to obtain data from columns that are not specifically
1392 published. If security is a consideration, protections can be applied
1393 at the publisher side.
1397 If no column list is specified, any columns added to the table later are
1398 automatically replicated. This means that having a column list which names
1399 all columns is not the same as having no column list at all.
1403 A column list can contain only simple column references. The order
1404 of columns in the list is not preserved.
1408 Specifying a column list when the publication also publishes
1409 <link linkend=
"sql-createpublication-params-for-tables-in-schema"><literal>FOR TABLES IN SCHEMA
</literal></link>
1414 For partitioned tables, the publication parameter
1415 <link linkend=
"sql-createpublication-params-with-publish-via-partition-root"><literal>publish_via_partition_root
</literal></link>
1416 determines which column list is used. If
<literal>publish_via_partition_root
</literal>
1417 is
<literal>true
</literal>, the root partitioned table's column list is
1418 used. Otherwise, if
<literal>publish_via_partition_root
</literal> is
1419 <literal>false
</literal> (the default), each partition's column list is used.
1423 If a publication publishes
<command>UPDATE
</command> or
1424 <command>DELETE
</command> operations, any column list must include the
1425 table's replica identity columns (see
1426 <xref linkend=
"sql-altertable-replica-identity"/>).
1427 If a publication publishes only
<command>INSERT
</command> operations, then
1428 the column list may omit replica identity columns.
1432 Column lists have no effect for the
<literal>TRUNCATE
</literal> command.
1436 During initial data synchronization, only the published columns are
1437 copied. However, if the subscriber is from a release prior to
15, then
1438 all the columns in the table are copied during initial data synchronization,
1439 ignoring any column lists.
1442 <warning id=
"logical-replication-col-list-combining">
1443 <title>Warning: Combining Column Lists from Multiple Publications
</title>
1445 There's currently no support for subscriptions comprising several
1446 publications where the same table has been published with different
1447 column lists.
<xref linkend=
"sql-createsubscription"/> disallows
1448 creating such subscriptions, but it is still possible to get into
1449 that situation by adding or altering column lists on the publication
1450 side after a subscription has been created.
1453 This means changing the column lists of tables on publications that are
1454 already subscribed could lead to errors being thrown on the subscriber
1458 If a subscription is affected by this problem, the only way to resume
1459 replication is to adjust one of the column lists on the publication
1460 side so that they all match; and then either recreate the subscription,
1461 or use
<link linkend=
"sql-altersubscription-params-setadddrop-publication">
1462 <literal>ALTER SUBSCRIPTION ... DROP PUBLICATION
</literal></link> to
1463 remove one of the offending publications and add it again.
1467 <sect2 id=
"logical-replication-col-list-examples">
1468 <title>Examples
</title>
1471 Create a table
<literal>t1
</literal> to be used in the following example.
1473 test_pub=# CREATE TABLE t1(id int, a text, b text, c text, d text, e text, PRIMARY KEY(id));
1475 </programlisting></para>
1478 Create a publication
<literal>p1
</literal>. A column list is defined for
1479 table
<literal>t1
</literal> to reduce the number of columns that will be
1480 replicated. Notice that the order of column names in the column list does
1483 test_pub=# CREATE PUBLICATION p1 FOR TABLE t1 (id, b, a, d);
1485 </programlisting></para>
1488 <literal>psql
</literal> can be used to show the column lists (if defined)
1489 for each publication.
1493 Owner | All tables | Inserts | Updates | Deletes | Truncates | Via root
1494 ----------+------------+---------+---------+---------+-----------+----------
1495 postgres | f | t | t | t | t | f
1497 "public.t1" (id, a, b, d)
1498 </programlisting></para>
1501 <literal>psql
</literal> can be used to show the column lists (if defined)
1506 Column | Type | Collation | Nullable | Default
1507 --------+---------+-----------+----------+---------
1508 id | integer | | not null |
1515 "t1_pkey" PRIMARY KEY, btree (id)
1518 </programlisting></para>
1521 On the subscriber node, create a table
<literal>t1
</literal> which now
1522 only needs a subset of the columns that were on the publisher table
1523 <literal>t1
</literal>, and also create the subscription
1524 <literal>s1
</literal> that subscribes to the publication
1525 <literal>p1
</literal>.
1527 test_sub=# CREATE TABLE t1(id int, b text, a text, d text, PRIMARY KEY(id));
1529 test_sub=# CREATE SUBSCRIPTION s1
1530 test_sub-# CONNECTION 'host=localhost dbname=test_pub application_name=s1'
1531 test_sub-# PUBLICATION p1;
1533 </programlisting></para>
1536 On the publisher node, insert some rows to table
<literal>t1
</literal>.
1538 test_pub=# INSERT INTO t1 VALUES(
1, 'a-
1', 'b-
1', 'c-
1', 'd-
1', 'e-
1');
1540 test_pub=# INSERT INTO t1 VALUES(
2, 'a-
2', 'b-
2', 'c-
2', 'd-
2', 'e-
2');
1542 test_pub=# INSERT INTO t1 VALUES(
3, 'a-
3', 'b-
3', 'c-
3', 'd-
3', 'e-
3');
1544 test_pub=# SELECT * FROM t1 ORDER BY id;
1545 id | a | b | c | d | e
1546 ----+-----+-----+-----+-----+-----
1547 1 | a-
1 | b-
1 | c-
1 | d-
1 | e-
1
1548 2 | a-
2 | b-
2 | c-
2 | d-
2 | e-
2
1549 3 | a-
3 | b-
3 | c-
3 | d-
3 | e-
3
1551 </programlisting></para>
1554 Only data from the column list of publication
<literal>p1
</literal> is
1557 test_sub=# SELECT * FROM t1 ORDER BY id;
1559 ----+-----+-----+-----
1564 </programlisting></para>
1570 <sect1 id=
"logical-replication-conflicts">
1571 <title>Conflicts
</title>
1574 Logical replication behaves similarly to normal DML operations in that
1575 the data will be updated even if it was changed locally on the subscriber
1576 node. If incoming data violates any constraints the replication will
1577 stop. This is referred to as a
<firstterm>conflict
</firstterm>. When
1578 replicating
<command>UPDATE
</command> or
<command>DELETE
</command>
1579 operations, missing data is also considered as a
1580 <firstterm>conflict
</firstterm>, but does not result in an error and such
1581 operations will simply be skipped.
1585 Additional logging is triggered, and the conflict statistics are collected (displayed in the
1586 <link linkend=
"monitoring-pg-stat-subscription-stats"><structname>pg_stat_subscription_stats
</structname></link> view)
1587 in the following
<firstterm>conflict
</firstterm> cases:
1589 <varlistentry id=
"conflict-insert-exists" xreflabel=
"insert_exists">
1590 <term><literal>insert_exists
</literal></term>
1593 Inserting a row that violates a
<literal>NOT DEFERRABLE
</literal>
1594 unique constraint. Note that to log the origin and commit
1595 timestamp details of the conflicting key,
1596 <link linkend=
"guc-track-commit-timestamp"><varname>track_commit_timestamp
</varname></link>
1597 should be enabled on the subscriber. In this case, an error will be
1598 raised until the conflict is resolved manually.
1602 <varlistentry id=
"conflict-update-origin-differs" xreflabel=
"update_origin_differs">
1603 <term><literal>update_origin_differs
</literal></term>
1606 Updating a row that was previously modified by another origin.
1607 Note that this conflict can only be detected when
1608 <link linkend=
"guc-track-commit-timestamp"><varname>track_commit_timestamp
</varname></link>
1609 is enabled on the subscriber. Currently, the update is always applied
1610 regardless of the origin of the local row.
1614 <varlistentry id=
"conflict-update-exists" xreflabel=
"update_exists">
1615 <term><literal>update_exists
</literal></term>
1618 The updated value of a row violates a
<literal>NOT DEFERRABLE
</literal>
1619 unique constraint. Note that to log the origin and commit
1620 timestamp details of the conflicting key,
1621 <link linkend=
"guc-track-commit-timestamp"><varname>track_commit_timestamp
</varname></link>
1622 should be enabled on the subscriber. In this case, an error will be
1623 raised until the conflict is resolved manually. Note that when updating a
1624 partitioned table, if the updated row value satisfies another partition
1625 constraint resulting in the row being inserted into a new partition, the
1626 <literal>insert_exists
</literal> conflict may arise if the new row
1627 violates a
<literal>NOT DEFERRABLE
</literal> unique constraint.
1631 <varlistentry id=
"conflict-update-missing" xreflabel=
"update_missing">
1632 <term><literal>update_missing
</literal></term>
1635 The tuple to be updated was not found. The update will simply be
1636 skipped in this scenario.
1640 <varlistentry id=
"conflict-delete-origin-differs" xreflabel=
"delete_origin_differs">
1641 <term><literal>delete_origin_differs
</literal></term>
1644 Deleting a row that was previously modified by another origin. Note that
1645 this conflict can only be detected when
1646 <link linkend=
"guc-track-commit-timestamp"><varname>track_commit_timestamp
</varname></link>
1647 is enabled on the subscriber. Currently, the delete is always applied
1648 regardless of the origin of the local row.
1652 <varlistentry id=
"conflict-delete-missing" xreflabel=
"delete_missing">
1653 <term><literal>delete_missing
</literal></term>
1656 The tuple to be deleted was not found. The delete will simply be
1657 skipped in this scenario.
1662 Note that there are other conflict scenarios, such as exclusion constraint
1663 violations. Currently, we do not provide additional details for them in the
1668 The log format for logical replication conflicts is as follows:
1670 LOG: conflict detected on relation
"<replaceable>schemaname</replaceable>.<replaceable>tablename</replaceable>": conflict=
<replaceable>conflict_type
</replaceable>
1671 DETAIL:
<replaceable class=
"parameter">detailed_explanation
</replaceable>.
1672 {
<replaceable class=
"parameter">detail_values
</replaceable> [; ... ]}.
1674 <phrase>where
<replaceable class=
"parameter">detail_values
</replaceable> is one of:
</phrase>
1676 <literal>Key
</literal> (
<replaceable>column_name
</replaceable> <optional>, ...
</optional>)=(
<replaceable>column_value
</replaceable> <optional>, ...
</optional>)
1677 <literal>existing local tuple
</literal> <optional>(
<replaceable>column_name
</replaceable> <optional>, ...
</optional>)=
</optional>(
<replaceable>column_value
</replaceable> <optional>, ...
</optional>)
1678 <literal>remote tuple
</literal> <optional>(
<replaceable>column_name
</replaceable> <optional>, ...
</optional>)=
</optional>(
<replaceable>column_value
</replaceable> <optional>, ...
</optional>)
1679 <literal>replica identity
</literal> {(
<replaceable>column_name
</replaceable> <optional>, ...
</optional>)=(
<replaceable>column_value
</replaceable> <optional>, ...
</optional>) | full
<optional>(
<replaceable>column_name
</replaceable> <optional>, ...
</optional>)=
</optional>(
<replaceable>column_value
</replaceable> <optional>, ...
</optional>)}
1682 The log provides the following information:
1685 <term><literal>LOG
</literal></term>
1690 <replaceable>schemaname
</replaceable>.
<replaceable>tablename
</replaceable>
1691 identifies the local relation involved in the conflict.
1696 <replaceable>conflict_type
</replaceable> is the type of conflict that occurred
1697 (e.g.,
<literal>insert_exists
</literal>,
<literal>update_exists
</literal>).
1705 <term><literal>DETAIL
</literal></term>
1710 <replaceable class=
"parameter">detailed_explanation
</replaceable> includes
1711 the origin, transaction ID, and commit timestamp of the transaction that
1712 modified the existing local tuple, if available.
1717 The
<literal>Key
</literal> section includes the key values of the local
1718 tuple that violated a unique constraint for
1719 <literal>insert_exists
</literal> or
<literal>update_exists
</literal>
1725 The
<literal>existing local tuple
</literal> section includes the local
1726 tuple if its origin differs from the remote tuple for
1727 <literal>update_origin_differs
</literal> or
<literal>delete_origin_differs
</literal>
1728 conflicts, or if the key value conflicts with the remote tuple for
1729 <literal>insert_exists
</literal> or
<literal>update_exists
</literal>
1735 The
<literal>remote tuple
</literal> section includes the new tuple from
1736 the remote insert or update operation that caused the conflict. Note that
1737 for an update operation, the column value of the new tuple will be null
1738 if the value is unchanged and toasted.
1743 The
<literal>replica identity
</literal> section includes the replica
1744 identity key values that were used to search for the existing local
1745 tuple to be updated or deleted. This may include the full tuple value
1746 if the local relation is marked with
1747 <link linkend=
"sql-altertable-replica-identity-full"><literal>REPLICA IDENTITY FULL
</literal></link>.
1752 <replaceable class=
"parameter">column_name
</replaceable> is the column name.
1753 For
<literal>existing local tuple
</literal>,
<literal>remote tuple
</literal>,
1754 and
<literal>replica identity full
</literal> cases, column names are
1755 logged only if the user lacks the privilege to access all columns of
1756 the table. If column names are present, they appear in the same order
1757 as the corresponding column values.
1762 <replaceable class=
"parameter">column_value
</replaceable> is the column value.
1763 The large column values are truncated to
64 bytes.
1773 Logical replication operations are performed with the privileges of the role
1774 which owns the subscription. Permissions failures on target tables will
1775 cause replication conflicts, as will enabled
1776 <link linkend=
"ddl-rowsecurity">row-level security
</link> on target tables
1777 that the subscription owner is subject to, without regard to whether any
1778 policy would ordinarily reject the
<command>INSERT
</command>,
1779 <command>UPDATE
</command>,
<command>DELETE
</command> or
1780 <command>TRUNCATE
</command> which is being replicated. This restriction on
1781 row-level security may be lifted in a future version of
1782 <productname>PostgreSQL
</productname>.
1786 A conflict that produces an error will stop the replication; it must be
1787 resolved manually by the user. Details about the conflict can be found in
1788 the subscriber's server log.
1792 The resolution can be done either by changing data or permissions on the subscriber so
1793 that it does not conflict with the incoming change or by skipping the
1794 transaction that conflicts with the existing data. When a conflict produces
1795 an error, the replication won't proceed, and the logical replication worker will
1796 emit the following kind of message to the subscriber's server log:
1798 ERROR: conflict detected on relation
"public.test": conflict=insert_exists
1799 DETAIL: Key already exists in unique index
"t_pkey", which was modified locally in transaction
740 at
2024-
06-
26 10:
47:
04.727375+
08.
1800 Key (c)=(
1); existing local tuple (
1, 'local'); remote tuple (
1, 'remote').
1801 CONTEXT: processing remote data for replication origin
"pg_16395" during
"INSERT" for replication target relation
"public.test" in transaction
725 finished at
0/
14C0378
1803 The LSN of the transaction that contains the change violating the constraint and
1804 the replication origin name can be found from the server log (LSN
0/
14C0378 and
1805 replication origin
<literal>pg_16395
</literal> in the above case). The
1806 transaction that produced the conflict can be skipped by using
1807 <link linkend=
"sql-altersubscription-params-skip"><command>ALTER SUBSCRIPTION ... SKIP
</command></link>
1809 (i.e., LSN
0/
14C0378). The finish LSN could be an LSN at which the transaction
1810 is committed or prepared on the publisher. Alternatively, the transaction can
1811 also be skipped by calling the
<link linkend=
"pg-replication-origin-advance">
1812 <function>pg_replication_origin_advance()
</function></link> function.
1813 Before using this function, the subscription needs to be disabled temporarily
1814 either by
<link linkend=
"sql-altersubscription-params-disable">
1815 <command>ALTER SUBSCRIPTION ... DISABLE
</command></link> or, the
1816 subscription can be used with the
1817 <link linkend=
"sql-createsubscription-params-with-disable-on-error"><literal>disable_on_error
</literal></link>
1818 option. Then, you can use
<function>pg_replication_origin_advance()
</function>
1819 function with the
<parameter>node_name
</parameter> (i.e.,
<literal>pg_16395
</literal>)
1820 and the next LSN of the finish LSN (i.e.,
0/
14C0379). The current position of
1821 origins can be seen in the
<link linkend=
"view-pg-replication-origin-status">
1822 <structname>pg_replication_origin_status
</structname></link> system view.
1823 Please note that skipping the whole transaction includes skipping changes that
1824 might not violate any constraint. This can easily make the subscriber
1826 The additional details regarding conflicting rows, such as their origin and
1827 commit timestamp can be seen in the
<literal>DETAIL
</literal> line of the
1828 log. But note that this information is only available when
1829 <link linkend=
"guc-track-commit-timestamp"><varname>track_commit_timestamp
</varname></link>
1830 is enabled on the subscriber. Users can use this information to decide
1831 whether to retain the local change or adopt the remote alteration. For
1832 instance, the
<literal>DETAIL
</literal> line in the above log indicates that
1833 the existing row was modified locally. Users can manually perform a
1839 <link linkend=
"sql-createsubscription-params-with-streaming"><literal>streaming
</literal></link>
1840 mode is
<literal>parallel
</literal>, the finish LSN of failed transactions
1841 may not be logged. In that case, it may be necessary to change the streaming
1842 mode to
<literal>on
</literal> or
<literal>off
</literal> and cause the same
1843 conflicts again so the finish LSN of the failed transaction will be written
1844 to the server log. For the usage of finish LSN, please refer to
<link
1845 linkend=
"sql-altersubscription"><command>ALTER SUBSCRIPTION ...
1846 SKIP
</command></link>.
1850 <sect1 id=
"logical-replication-restrictions">
1851 <title>Restrictions
</title>
1854 Logical replication currently has the following restrictions or missing
1855 functionality. These might be addressed in future releases.
1861 The database schema and DDL commands are not replicated. The initial
1862 schema can be copied by hand using
<literal>pg_dump
1863 --schema-only
</literal>. Subsequent schema changes would need to be kept
1864 in sync manually. (Note, however, that there is no need for the schemas
1865 to be absolutely the same on both sides.) Logical replication is robust
1866 when schema definitions change in a live database: When the schema is
1867 changed on the publisher and replicated data starts arriving at the
1868 subscriber but does not fit into the table schema, replication will error
1869 until the schema is updated. In many cases, intermittent errors can be
1870 avoided by applying additive schema changes to the subscriber first.
1876 Sequence data is not replicated. The data in serial or identity columns
1877 backed by sequences will of course be replicated as part of the table,
1878 but the sequence itself would still show the start value on the
1879 subscriber. If the subscriber is used as a read-only database, then this
1880 should typically not be a problem. If, however, some kind of switchover
1881 or failover to the subscriber database is intended, then the sequences
1882 would need to be updated to the latest values, either by copying the
1883 current data from the publisher (perhaps
1884 using
<command>pg_dump
</command>) or by determining a sufficiently high
1885 value from the tables themselves.
1891 Replication of
<command>TRUNCATE
</command> commands is supported, but
1892 some care must be taken when truncating groups of tables connected by
1893 foreign keys. When replicating a truncate action, the subscriber will
1894 truncate the same group of tables that was truncated on the publisher,
1895 either explicitly specified or implicitly collected via
1896 <literal>CASCADE
</literal>, minus tables that are not part of the
1897 subscription. This will work correctly if all affected tables are part
1898 of the same subscription. But if some tables to be truncated on the
1899 subscriber have foreign-key links to tables that are not part of the same
1900 (or any) subscription, then the application of the truncate action on the
1901 subscriber will fail.
1907 Large objects (see
<xref linkend=
"largeobjects"/>) are not replicated.
1908 There is no workaround for that, other than storing data in normal
1915 Replication is only supported by tables, including partitioned tables.
1916 Attempts to replicate other types of relations, such as views, materialized
1917 views, or foreign tables, will result in an error.
1923 When replicating between partitioned tables, the actual replication
1924 originates, by default, from the leaf partitions on the publisher, so
1925 partitions on the publisher must also exist on the subscriber as valid
1926 target tables. (They could either be leaf partitions themselves, or they
1927 could be further subpartitioned, or they could even be independent
1928 tables.) Publications can also specify that changes are to be replicated
1929 using the identity and schema of the partitioned root table instead of
1930 that of the individual leaf partitions in which the changes actually
1932 <link linkend=
"sql-createpublication-params-with-publish-via-partition-root"><literal>publish_via_partition_root
</literal></link>
1933 parameter of
<command>CREATE PUBLICATION
</command>).
1940 <link linkend=
"sql-altertable-replica-identity-full"><literal>REPLICA IDENTITY FULL
</literal></link>
1941 on published tables, it is important to note that the
<literal>UPDATE
</literal>
1942 and
<literal>DELETE
</literal> operations cannot be applied to subscribers
1943 if the tables include attributes with datatypes (such as point or box)
1944 that do not have a default operator class for B-tree or Hash. However,
1945 this limitation can be overcome by ensuring that the table has a primary
1946 key or replica identity defined for it.
1952 <sect1 id=
"logical-replication-architecture">
1953 <title>Architecture
</title>
1956 Logical replication starts by copying a snapshot of the data on the
1957 publisher database. Once that is done, changes on the publisher are sent
1958 to the subscriber as they occur in real time. The subscriber applies data
1959 in the order in which commits were made on the publisher so that
1960 transactional consistency is guaranteed for the publications within any
1961 single subscription.
1965 Logical replication is built with an architecture similar to physical
1966 streaming replication (see
<xref linkend=
"streaming-replication"/>). It is
1967 implemented by
<literal>walsender
</literal> and
<literal>apply
</literal>
1968 processes. The walsender process starts logical decoding (described
1969 in
<xref linkend=
"logicaldecoding"/>) of the WAL and loads the standard
1970 logical decoding output plugin (
<literal>pgoutput
</literal>). The plugin
1971 transforms the changes read
1972 from WAL to the logical replication protocol
1973 (see
<xref linkend=
"protocol-logical-replication"/>) and filters the data
1974 according to the publication specification. The data is then continuously
1975 transferred using the streaming replication protocol to the apply worker,
1976 which maps the data to local tables and applies the individual changes as
1977 they are received, in correct transactional order.
1981 The apply process on the subscriber database always runs with
1982 <link linkend=
"guc-session-replication-role"><varname>session_replication_role
</varname></link>
1983 set to
<literal>replica
</literal>. This means that, by default,
1984 triggers and rules will not fire on a subscriber. Users can optionally choose to
1985 enable triggers and rules on a table using the
1986 <link linkend=
"sql-altertable"><command>ALTER TABLE
</command></link> command
1987 and the
<literal>ENABLE TRIGGER
</literal> and
<literal>ENABLE RULE
</literal>
1992 The logical replication apply process currently only fires row triggers,
1993 not statement triggers. The initial table synchronization, however, is
1994 implemented like a
<command>COPY
</command> command and thus fires both row
1995 and statement triggers for
<command>INSERT
</command>.
1998 <sect2 id=
"logical-replication-snapshot">
1999 <title>Initial Snapshot
</title>
2001 The initial data in existing subscribed tables are snapshotted and
2002 copied in a parallel instance of a special kind of apply process.
2003 This process will create its own replication slot and copy the existing
2004 data. As soon as the copy is finished the table contents will become
2005 visible to other backends. Once existing data is copied, the worker
2006 enters synchronization mode, which ensures that the table is brought
2007 up to a synchronized state with the main apply process by streaming
2008 any changes that happened during the initial data copy using standard
2009 logical replication. During this synchronization phase, the changes
2010 are applied and committed in the same order as they happened on the
2011 publisher. Once synchronization is done, control of the
2012 replication of the table is given back to the main apply process where
2013 replication continues as normal.
2018 <link linkend=
"sql-createpublication-params-with-publish"><literal>publish
</literal></link>
2019 parameter only affects what DML operations will be replicated. The
2020 initial data synchronization does not take this parameter into account
2021 when copying the existing table data.
2027 <sect1 id=
"logical-replication-monitoring">
2028 <title>Monitoring
</title>
2031 Because logical replication is based on a similar architecture as
2032 <link linkend=
"streaming-replication">physical streaming replication
</link>,
2033 the monitoring on a publication node is similar to monitoring of a
2034 physical replication primary
2035 (see
<xref linkend=
"streaming-replication-monitoring"/>).
2039 The monitoring information about subscription is visible in
2040 <link linkend=
"monitoring-pg-stat-subscription">
2041 <structname>pg_stat_subscription
</structname></link>.
2042 This view contains one row for every subscription worker. A subscription
2043 can have zero or more active subscription workers depending on its state.
2047 Normally, there is a single apply process running for an enabled
2048 subscription. A disabled subscription or a crashed subscription will have
2049 zero rows in this view. If the initial data synchronization of any
2050 table is in progress, there will be additional workers for the tables
2051 being synchronized. Moreover, if the
2052 <link linkend=
"sql-createsubscription-params-with-streaming"><literal>streaming
</literal></link>
2053 transaction is applied in parallel, there may be additional parallel apply
2058 <sect1 id=
"logical-replication-security">
2059 <title>Security
</title>
2062 The role used for the replication connection must have
2063 the
<literal>REPLICATION
</literal> attribute (or be a superuser). If the
2064 role lacks
<literal>SUPERUSER
</literal> and
<literal>BYPASSRLS
</literal>,
2065 publisher row security policies can execute. If the role does not trust
2066 all table owners, include
<literal>options=-crow_security=off
</literal> in
2067 the connection string; if a table owner then adds a row security policy,
2068 that setting will cause replication to halt rather than execute the policy.
2069 Access for the role must be configured in
<filename>pg_hba.conf
</filename>
2070 and it must have the
<literal>LOGIN
</literal> attribute.
2074 In order to be able to copy the initial table data, the role used for the
2075 replication connection must have the
<literal>SELECT
</literal> privilege on
2076 a published table (or be a superuser).
2080 To create a publication, the user must have the
<literal>CREATE
</literal>
2081 privilege in the database.
2085 To add tables to a publication, the user must have ownership rights on the
2086 table. To add all tables in schema to a publication, the user must be a
2087 superuser. To create a publication that publishes all tables or all tables in
2088 schema automatically, the user must be a superuser.
2092 There are currently no privileges on publications. Any subscription (that
2093 is able to connect) can access any publication. Thus, if you intend to
2094 hide some information from particular subscribers, such as by using row
2095 filters or column lists, or by not adding the whole table to the
2096 publication, be aware that other publications in the same database could
2097 expose the same information. Publication privileges might be added to
2098 <productname>PostgreSQL
</productname> in the future to allow for
2099 finer-grained access control.
2103 To create a subscription, the user must have the privileges of
2104 the
<literal>pg_create_subscription
</literal> role, as well as
2105 <literal>CREATE
</literal> privileges on the database.
2109 The subscription apply process will, at a session level, run with the
2110 privileges of the subscription owner. However, when performing an insert,
2111 update, delete, or truncate operation on a particular table, it will switch
2112 roles to the table owner and perform the operation with the table owner's
2113 privileges. This means that the subscription owner needs to be able to
2114 <literal>SET ROLE
</literal> to each role that owns a replicated table.
2118 If the subscription has been configured with
2119 <literal>run_as_owner = true
</literal>, then no user switching will
2120 occur. Instead, all operations will be performed with the permissions
2121 of the subscription owner. In this case, the subscription owner only
2122 needs privileges to
<literal>SELECT
</literal>,
<literal>INSERT
</literal>,
2123 <literal>UPDATE
</literal>, and
<literal>DELETE
</literal> from the
2124 target table, and does not need privileges to
<literal>SET ROLE
</literal>
2125 to the table owner. However, this also means that any user who owns
2126 a table into which replication is happening can execute arbitrary code with
2127 the privileges of the subscription owner. For example, they could do this
2128 by simply attaching a trigger to one of the tables which they own.
2129 Because it is usually undesirable to allow one role to freely assume
2130 the privileges of another, this option should be avoided unless user
2131 security within the database is of no concern.
2135 On the publisher, privileges are only checked once at the start of a
2136 replication connection and are not re-checked as each change record is read.
2140 On the subscriber, the subscription owner's privileges are re-checked for
2141 each transaction when applied. If a worker is in the process of applying a
2142 transaction when the ownership of the subscription is changed by a
2143 concurrent transaction, the application of the current transaction will
2144 continue under the old owner's privileges.
2148 <sect1 id=
"logical-replication-config">
2149 <title>Configuration Settings
</title>
2152 Logical replication requires several configuration options to be set. Most
2153 options are relevant only on one side of the replication. However,
2154 <varname>max_replication_slots
</varname> is used on both the publisher and
2155 the subscriber, but it has a different meaning for each.
2158 <sect2 id=
"logical-replication-config-publisher">
2159 <title>Publishers
</title>
2162 <link linkend=
"guc-wal-level"><varname>wal_level
</varname></link> must be
2163 set to
<literal>logical
</literal>.
2167 <link linkend=
"guc-max-replication-slots"><varname>max_replication_slots
</varname></link>
2168 must be set to at least the number of subscriptions expected to connect,
2169 plus some reserve for table synchronization.
2173 <link linkend=
"guc-max-wal-senders"><varname>max_wal_senders
</varname></link>
2174 should be set to at least the same as
2175 <varname>max_replication_slots
</varname>, plus the number of physical
2176 replicas that are connected at the same time.
2180 Logical replication walsender is also affected by
2181 <link linkend=
"guc-wal-sender-timeout"><varname>wal_sender_timeout
</varname></link>.
2186 <sect2 id=
"logical-replication-config-subscriber">
2187 <title>Subscribers
</title>
2190 <link linkend=
"guc-max-replication-slots-subscriber"><varname>max_replication_slots
</varname></link>
2191 must be set to at least the number of subscriptions that will be added to
2192 the subscriber, plus some reserve for table synchronization.
2196 <link linkend=
"guc-max-logical-replication-workers"><varname>max_logical_replication_workers
</varname></link>
2197 must be set to at least the number of subscriptions (for leader apply
2198 workers), plus some reserve for the table synchronization workers and
2199 parallel apply workers.
2203 <link linkend=
"guc-max-worker-processes"><varname>max_worker_processes
</varname></link>
2204 may need to be adjusted to accommodate for replication workers, at least
2205 (
<link linkend=
"guc-max-logical-replication-workers"><varname>max_logical_replication_workers
</varname></link>
2206 +
<literal>1</literal>). Note, some extensions and parallel queries also
2207 take worker slots from
<varname>max_worker_processes
</varname>.
2211 <link linkend=
"guc-max-sync-workers-per-subscription"><varname>max_sync_workers_per_subscription
</varname></link>
2212 controls the amount of parallelism of the initial data copy during the
2213 subscription initialization or when new tables are added.
2217 <link linkend=
"guc-max-parallel-apply-workers-per-subscription"><varname>max_parallel_apply_workers_per_subscription
</varname></link>
2218 controls the amount of parallelism for streaming of in-progress
2219 transactions with subscription parameter
2220 <literal>streaming = parallel
</literal>.
2224 Logical replication workers are also affected by
2225 <link linkend=
"guc-wal-receiver-timeout"><varname>wal_receiver_timeout
</varname></link>,
2226 <link linkend=
"guc-wal-receiver-status-interval"><varname>wal_receiver_status_interval
</varname></link> and
2227 <link linkend=
"guc-wal-retrieve-retry-interval"><varname>wal_retrieve_retry_interval
</varname></link>.
2234 <sect1 id=
"logical-replication-quick-setup">
2235 <title>Quick Setup
</title>
2238 First set the configuration options in
<filename>postgresql.conf
</filename>:
2242 The other required settings have default values that are sufficient for a
2247 <filename>pg_hba.conf
</filename> needs to be adjusted to allow replication
2248 (the values here depend on your actual network configuration and user you
2249 want to use for connecting):
2251 host all repuser
0.0.0.0/
0 md5
2256 Then on the publisher database:
2258 CREATE PUBLICATION mypub FOR TABLE users, departments;
2263 And on the subscriber database:
2265 CREATE SUBSCRIPTION mysub CONNECTION 'dbname=foo host=bar user=repuser' PUBLICATION mypub;
2270 The above will start the replication process, which synchronizes the
2271 initial table contents of the tables
<literal>users
</literal> and
2272 <literal>departments
</literal> and then starts replicating
2273 incremental changes to those tables.