Performing logical replication for Amazon RDS for PostgreSQL
Starting with version 10.4, RDS for PostgreSQL supports the publication and
subscription SQL syntax that was introduced in PostgreSQL 10. To learn more, see
Logical
replication
Note
In addition to the native PostgreSQL logical replication feature introduced
in PostgreSQL 10, RDS for PostgreSQL also supports the pglogical
extension. For more
information, see Using pglogical to synchronize
data across instances.
Following, you can find information about setting up logical replication for an RDS for PostgreSQL DB instance.
Understanding logical replication and logical decoding
RDS for PostgreSQL supports the streaming of write-ahead log (WAL) changes
using PostgreSQL's logical replication slots. It also supports using logical
decoding. You can set up logical replication slots on your instance and stream database
changes through these slots to a client such as pg_recvlogical
. You create
logical replication slots at the database level, and they support replication
connections to a single database.
The most common clients for PostgreSQL logical replication are AWS Database Migration Service or a custom-managed host on an Amazon EC2 instance. The logical replication slot has no information about the receiver of the stream. Also, there's no requirement that the target be a replica database. If you set up a logical replication slot and don't read from the slot, data can be written and quickly fill up your DB instance's storage.
You turn on PostgreSQL logical replication and logical decoding for Amazon RDS with a parameter, a replication connection type, and a security role. The client for logical decoding can be any client that can establish a replication connection to a database on a PostgreSQL DB instance.
To turn on logical decoding for an RDS for PostgreSQL DB instance
-
Make sure that the user account that you're using has these roles:
-
The
rds_superuser
role so you can turn on logical replication -
The
rds_replication
role to grant permissions to manage logical slots and to stream data using logical slots
-
-
Set the
rds.logical_replication
static parameter to 1. As part of applying this parameter, also set the parameterswal_level
,max_wal_senders
,max_replication_slots
, andmax_connections
. These parameter changes can increase WAL generation, so set therds.logical_replication
parameter only when you are using logical slots. -
Reboot the DB instance for the static
rds.logical_replication
parameter to take effect. -
Create a logical replication slot as explained in the next section. This process requires that you specify a decoding plugin. Currently, RDS for PostgreSQL supports the test_decoding and wal2json output plugins that ship with PostgreSQL.
For more information on PostgreSQL logical decoding, see the PostgreSQL documentation
Working with logical replication slots
You can use SQL commands to work with logical slots. For example, the
following command creates a logical slot named test_slot
using the default PostgreSQL output plugin
test_decoding
.
SELECT * FROM pg_create_logical_replication_slot('test_slot', 'test_decoding');
slot_name | xlog_position -----------------+--------------- regression_slot | 0/16B1970 (1 row)
To list logical slots, use the following command.
SELECT * FROM pg_replication_slots;
To drop a logical slot, use the following command.
SELECT pg_drop_replication_slot('test_slot');
pg_drop_replication_slot ----------------------- (1 row)
For more examples on working with logical replication slots, see
Logical decoding examples
After you create the logical replication slot, you can start streaming. The following example shows how logical decoding is controlled over the streaming replication protocol. This example uses the program pg_recvlogical, which is included in the PostgreSQL distribution. Doing this requires that client authentication is set up to allow replication connections.
pg_recvlogical -d postgres --slot test_slot -U postgres --host -
instance-name.111122223333
.aws-region
.rds.amazonaws.com -f - --start
To see the contents of the pg_replication_origin_status
view, query the pg_show_replication_origin_status
function.
SELECT * FROM pg_show_replication_origin_status();
local_id | external_id | remote_lsn | local_lsn ----------+-------------+------------+----------- (0 rows)