Help Center/ Relational Database Service/ Best Practices/ RDS for PostgreSQL/ RDS for PostgreSQL Publications and Subscriptions
Updated on 2024-09-06 GMT+08:00

RDS for PostgreSQL Publications and Subscriptions

Logical Definition

A publication can be defined on any primary physical replication server. The node where a publication is defined is called the publisher. A publication is a set of changes generated from a table or a group of tables, and might also be described as a change set or replication set. Each publication exists in only one database.

A subscription is the downstream side of logical replication. The node where a subscription is defined is called the subscriber. A subscription defines the connection to another database and the set of publications (one or more) to which it wants to subscribe. The subscriber database behaves in the same way as any other RDS for PostgreSQL instance (primary) and can be used as a publisher for other databases by defining its own publications.

Required Permissions

  • To create a publication, the publisher must have the replication permission.
  • When creating a publication for ALL TABLES, ensure that the publisher uses the root user of the initial or later versions for privilege escalation.
  • When creating or deleting a subscription, ensure that the subscriber uses the root user of the initial or later versions for privilege escalation.
  • When creating a publication or subscription, ensure that the publisher and subscriber are in the same VPC.

For details about root privilege escalation of each version, see Privileges of the root User.

Restrictions on Publications

  • Publications may currently only contain tables (indexes, sequence numbers, and materialized views cannot be published). Each table can be added to multiple publications if needed.
  • One publication can have multiple subscribers.
  • ALL TABLES can be used to publish all tables.
  • Multiple publications can be created in a given database, but each publication must have a unique name. The created publications can be obtained by querying pg_publication.
  • Publications can choose to limit the changes they produce to any combination of INSERT, UPDATE, DELETE, and TRUNCATE, similar to how triggers are fired by particular event types. By default, all operation types are replicated.

    Example: To publish the UPDATE and DELETE operations on the t1 table:

    CREATE PUBLICATION update_delete_only FOR TABLE t1
        WITH (publish = 'update, delete') ;
  • Replica identity: A published table must have a replica identity configured in order to be able to replicate UPDATE and DELETE operations. If nothing is set for the replica identity, subsequent UPDATE or DELETE operations will cause an error on the publisher.

    You can obtain the replica identity of a table from pg_class.relreplident.

    relreplident is of character type and identifies columns used to form "replica identity" for rows: d = default, f = all columns, i = index, and n = nothing.

    To check whether a table has an index constraint that can be used as a replica identity, run the following:

    SELECT quote_ident(nspname) || '.' || quote_ident(relname) AS name, con.ri AS keys,
           CASE relreplident WHEN 'd' THEN 'default' WHEN 'n' THEN 'nothing' WHEN 'f' THEN 'full' WHEN 'i' THEN 'index' END AS replica_identity
    FROM pg_class c JOIN pg_namespace n ON c.relnamespace = n.oid, LATERAL (SELECT array_agg(contype) AS ri FROM pg_constraint WHERE conrelid = c.oid) con
    WHERE relkind = 'r' AND nspname NOT IN ('pg_catalog', 'information_schema', 'monitor', 'repack', 'pg_toast')
    ORDER BY 2,3;
  • Command for changing a replica identity

    The replica identity of a table can be changed using ALTER TABLE.

    ALTER TABLE table_name REPLICA IDENTITY 
    { DEFAULT | USING INDEX index_name | FULL | NOTHING };
    -- There are four forms:
    ALTER TABLE t_normal REPLICA IDENTITY DEFAULT;                    -- The primary key is used as the replica identity. If there is no primary key, the replica identity is set to FULL.
    ALTER TABLE t_normal REPLICA IDENTITY FULL;                       -- The entire row is used as the replica identity.
    ALTER TABLE t_normal REPLICA IDENTITY USING INDEX t_normal_v_key; -- A unique index is used as the replica identity.
    ALTER TABLE t_normal REPLICA IDENTITY NOTHING;                    -- No replica identity is set.
  • Precautions for using replica identities
    • If a table has a primary key, the replica identity can be set to DEFAULT.
    • If a table does not have a primary key but has a non-null unique index, the replica identity can be set to INDEX.
    • If a table does not have a primary key or a non-null unique index, the replica identity can be set to FULL. This, however, is very inefficient and should only be used as a fallback if no other solution is possible.
    • In all cases other than those mentioned above, logical replication cannot be implemented. The output information is insufficient, and an error may be reported.
    • If a table with replica identity "nothing" is added to logical replication, deleting or updating the table will cause an error on the publisher.

Restrictions on Subscriptions

  • To ensure that failover slots are used, failover slots must be created on the publisher and associated with the existing replication slots using create_slot = false.

    CREATE SUBSCRIPTION sub1 CONNECTION 'host=192.168.0.1 port=5432 user=user1 dbname=db1' PUBLICATION pub_name with (create_slot = false,slot_name = FailoverSlot_name);

  • Logical replication does not replicate DDL changes, so the tables in the publication set must already exist on the subscriber.
  • Multiple subscriptions can be created in a given database. These subscriptions can come from one or more publishers.
  • A given table of a subscriber cannot accept multiple publications from the same source.
  • When creating a subscription or altering a subscription, you can use enable to enable the subscription or disable to suspend the subscription.
  • To delete a subscription, use DROP SUBSCRIPTION. Note that after a subscription is deleted, the local table and data are not deleted, but upstream information of the subscription is no longer received.

    If a subscription is associated with a replication slot, DROP SUBSCRIPTION cannot be executed inside a transaction block. You can use ALTER SUBSCRIPTION to disassociate the subscription from the replication slot.

    To completely delete a subscription, perform the following steps:

    1. Query the replication slot associated with the subscription on the subscriber.

      select subname,subconninfo,subslotname from pg_subscription where subname = 'sub2';

      • subname indicates the subscriber name.
      • subconninfo indicates information about the connected remote host.
      • subslotname indicates the replication slot name of the remote host.
    2. On the subscriber, disassociate the subscription from the replication slot and delete the subscription.

      ALTER SUBSCRIPTION subname SET (slot_name = NONE);

      DROP SUBSCRIPTION subname;

    3. Delete the associated replication slot at the publisher.

      select pg_drop_replication_slot(' slot_name);

Syntax Reference

  • Publications

    CREATE PUBLICATION is used to create a publication, DROP PUBLICATION is used to delete a publication, and ALTER PUBLICATION is used to modify a publication.

    After a publication is created, tables can be added or removed dynamically using ALTER PUBLICATION. Such operations are all transactional.

  • Subscriptions

    CREATE SUBSCRIPTION is used to create a subscription, DROP SUBSCRIPTION is used to delete a subscription, and ALTER SUBSCRIPTION is used to modify a subscription.

    After creating a subscription, you can use ALTER SUBSCRIPTION to suspend or resume the subscription at any time. Deleting and recreating a subscription results in the loss of synchronized information, which means that related data needs to be synchronized again.

For details, see the official documentation. PostgreSQL 13 is used as an example.