Logical Decoding Logical Decoding PostgreSQL provides infrastructure to stream the modifications performed via SQL to external consumers. This functionality can be used for a variety of purposes, including replication solutions and auditing. Changes are sent out in streams identified by logical replication slots. The format in which those changes are streamed is determined by the output plugin used. An example plugin is provided in the PostgreSQL distribution. Additional plugins can be written to extend the choice of available formats without modifying any core code. Every output plugin has access to each individual new row produced by INSERT and the new row version created by UPDATE. Availability of old row versions for UPDATE and DELETE depends on the configured replica identity (see ). Changes can be consumed either using the streaming replication protocol (see and ), or by calling functions via SQL (see ). It is also possible to write additional methods of consuming the output of a replication slot without modifying core code (see ). Logical Decoding Examples The following example demonstrates controlling logical decoding using the SQL interface. Before you can use logical decoding, you must set to logical and to at least 1. Then, you should connect to the target database (in the example below, postgres) as a superuser. postgres=# -- Create a slot named 'regression_slot' using the output plugin 'test_decoding' postgres=# SELECT * FROM pg_create_logical_replication_slot('regression_slot', 'test_decoding'); slot_name | xlog_position -----------------+--------------- regression_slot | 0/16B1970 (1 row) postgres=# SELECT slot_name, plugin, slot_type, database, active, restart_lsn, confirmed_flush_lsn FROM pg_replication_slots; slot_name | plugin | slot_type | database | active | restart_lsn | confirmed_flush_lsn -----------------+---------------+-----------+----------+--------+-------------+----------------- regression_slot | test_decoding | logical | postgres | f | 0/16A4408 | 0/16A4440 (1 row) postgres=# -- There are no changes to see yet postgres=# SELECT * FROM pg_logical_slot_get_changes('regression_slot', NULL, NULL); location | xid | data ----------+-----+------ (0 rows) postgres=# CREATE TABLE data(id serial primary key, data text); CREATE TABLE postgres=# -- DDL isn't replicated, so all you'll see is the transaction postgres=# SELECT * FROM pg_logical_slot_get_changes('regression_slot', NULL, NULL); location | xid | data -----------+-----+------------ 0/16D5D48 | 688 | BEGIN 688 0/16E0380 | 688 | COMMIT 688 (2 rows) postgres=# -- Once changes are read, they're consumed and not emitted postgres=# -- in a subsequent call: postgres=# SELECT * FROM pg_logical_slot_get_changes('regression_slot', NULL, NULL); location | xid | data ----------+-----+------ (0 rows) postgres=# BEGIN; postgres=# INSERT INTO data(data) VALUES('1'); postgres=# INSERT INTO data(data) VALUES('2'); postgres=# COMMIT; postgres=# SELECT * FROM pg_logical_slot_get_changes('regression_slot', NULL, NULL); location | xid | data -----------+-----+----------------------------------------------- 0/16E0478 | 689 | BEGIN 689 0/16E0478 | 689 | table public.data: INSERT: id[integer]:1 data[text]:'1' 0/16E0580 | 689 | table public.data: INSERT: id[integer]:2 data[text]:'2' 0/16E0650 | 689 | COMMIT 689 (4 rows) postgres=# INSERT INTO data(data) VALUES('3'); postgres=# -- You can also peek ahead in the change stream without consuming changes postgres=# SELECT * FROM pg_logical_slot_peek_changes('regression_slot', NULL, NULL); location | xid | data -----------+-----+----------------------------------------------- 0/16E09C0 | 690 | BEGIN 690 0/16E09C0 | 690 | table public.data: INSERT: id[integer]:3 data[text]:'3' 0/16E0B90 | 690 | COMMIT 690 (3 rows) postgres=# -- The next call to pg_logical_slot_peek_changes() returns the same changes again postgres=# SELECT * FROM pg_logical_slot_peek_changes('regression_slot', NULL, NULL); location | xid | data -----------+-----+----------------------------------------------- 0/16E09C0 | 690 | BEGIN 690 0/16E09C0 | 690 | table public.data: INSERT: id[integer]:3 data[text]:'3' 0/16E0B90 | 690 | COMMIT 690 (3 rows) postgres=# -- options can be passed to output plugin, to influence the formatting postgres=# SELECT * FROM pg_logical_slot_peek_changes('regression_slot', NULL, NULL, 'include-timestamp', 'on'); location | xid | data -----------+-----+----------------------------------------------- 0/16E09C0 | 690 | BEGIN 690 0/16E09C0 | 690 | table public.data: INSERT: id[integer]:3 data[text]:'3' 0/16E0B90 | 690 | COMMIT 690 (at 2014-02-27 16:41:51.863092+01) (3 rows) postgres=# -- Remember to destroy a slot you no longer need to stop it consuming postgres=# -- server resources: postgres=# SELECT pg_drop_replication_slot('regression_slot'); pg_drop_replication_slot ----------------------- (1 row) The following example shows how logical decoding is controlled over the streaming replication protocol, using the program included in the PostgreSQL distribution. This requires that client authentication is set up to allow replication connections (see ) and that max_wal_senders is set sufficiently high to allow an additional connection. $ pg_recvlogical -d postgres --slot test --create-slot $ pg_recvlogical -d postgres --slot test --start -f - ControlZ $ psql -d postgres -c "INSERT INTO data(data) VALUES('4');" $ fg BEGIN 693 table public.data: INSERT: id[integer]:4 data[text]:'4' COMMIT 693 ControlC $ pg_recvlogical -d postgres --slot test --drop-slot Logical Decoding Concepts Logical Decoding Logical Decoding Logical decoding is the process of extracting all persistent changes to a database's tables into a coherent, easy to understand format which can be interpreted without detailed knowledge of the database's internal state. In PostgreSQL, logical decoding is implemented by decoding the contents of the write-ahead log, which describe changes on a storage level, into an application-specific form such as a stream of tuples or SQL statements. Replication Slots replication slot logical replication In the context of logical replication, a slot represents a stream of changes that can be replayed to a client in the order they were made on the origin server. Each slot streams a sequence of changes from a single database. PostgreSQL also has streaming replication slots (see ), but they are used somewhat differently there. A replication slot has an identifier that is unique across all databases in a PostgreSQL cluster. Slots persist independently of the connection using them and are crash-safe. A logical slot will emit each change just once in normal operation. The current position of each slot is persisted only at checkpoint, so in the case of a crash the slot may return to an earlier LSN, which will then cause recent changes to be resent when the server restarts. Logical decoding clients are responsible for avoiding ill effects from handling the same message more than once. Clients may wish to record the last LSN they saw when decoding and skip over any repeated data or (when using the replication protocol) request that decoding start from that LSN rather than letting the server determine the start point. The Replication Progress Tracking feature is designed for this purpose, refer to replication origins. Multiple independent slots may exist for a single database. Each slot has its own state, allowing different consumers to receive changes from different points in the database change stream. For most applications, a separate slot will be required for each consumer. A logical replication slot knows nothing about the state of the receiver(s). It's even possible to have multiple different receivers using the same slot at different times; they'll just get the changes following on from when the last receiver stopped consuming them. Only one receiver may consume changes from a slot at any given time. Replication slots persist across crashes and know nothing about the state of their consumer(s). They will prevent removal of required resources even when there is no connection using them. This consumes storage because neither required WAL nor required rows from the system catalogs can be removed by VACUUM as long as they are required by a replication slot. So if a slot is no longer required it should be dropped. Output Plugins Output plugins transform the data from the write-ahead log's internal representation into the format the consumer of a replication slot desires. Exported Snapshots When a new replication slot is created using the streaming replication interface, a snapshot is exported (see ), which will show exactly the state of the database after which all changes will be included in the change stream. This can be used to create a new replica by using SET TRANSACTION SNAPSHOT to read the state of the database at the moment the slot was created. This transaction can then be used to dump the database's state at that point in time, which afterwards can be updated using the slot's contents without losing any changes. Streaming Replication Protocol Interface The commands CREATE_REPLICATION_SLOT slot_name LOGICAL output_plugin DROP_REPLICATION_SLOT slot_name START_REPLICATION SLOT slot_name LOGICAL ... are used to create, drop, and stream changes from a replication slot, respectively. These commands are only available over a replication connection; they cannot be used via SQL. See for details on these commands. The command can be used to control logical decoding over a streaming replication connection. (It uses these commands internally.) Logical Decoding <acronym>SQL</acronym> Interface See for detailed documentation on the SQL-level API for interacting with logical decoding. Synchronous replication (see ) is only supported on replication slots used over the streaming replication interface. The function interface and additional, non-core interfaces do not support synchronous replication. System Catalogs Related to Logical Decoding The pg_replication_slots view and the pg_stat_replication view provide information about the current state of replication slots and streaming replication connections respectively. These views apply to both physical and logical replication. Logical Decoding Output Plugins An example output plugin can be found in the contrib/test_decoding subdirectory of the PostgreSQL source tree. Initialization Function _PG_output_plugin_init An output plugin is loaded by dynamically loading a shared library with the output plugin's name as the library base name. The normal library search path is used to locate the library. To provide the required output plugin callbacks and to indicate that the library is actually an output plugin it needs to provide a function named _PG_output_plugin_init. This function is passed a struct that needs to be filled with the callback function pointers for individual actions. typedef struct OutputPluginCallbacks { LogicalDecodeStartupCB startup_cb; LogicalDecodeBeginCB begin_cb; LogicalDecodeChangeCB change_cb; LogicalDecodeCommitCB commit_cb; LogicalDecodeMessageCB message_cb; LogicalDecodeFilterByOriginCB filter_by_origin_cb; LogicalDecodeShutdownCB shutdown_cb; } OutputPluginCallbacks; typedef void (*LogicalOutputPluginInit)(struct OutputPluginCallbacks *cb); The begin_cb, change_cb and commit_cb callbacks are required, while startup_cb, filter_by_origin_cb and shutdown_cb are optional. Capabilities To decode, format and output changes, output plugins can use most of the backend's normal infrastructure, including calling output functions. Read only access to relations is permitted as long as only relations are accessed that either have been created by initdb in the pg_catalog schema, or have been marked as user provided catalog tables using ALTER TABLE user_catalog_table SET (user_catalog_table = true); CREATE TABLE another_catalog_table(data text) WITH (user_catalog_table = true); Any actions leading to transaction ID assignment are prohibited. That, among others, includes writing to tables, performing DDL changes, and calling txid_current(). Output Modes Output plugin callbacks can pass data to the consumer in nearly arbitrary formats. For some use cases, like viewing the changes via SQL, returning data in a data type that can contain arbitrary data (e.g., bytea) is cumbersome. If the output plugin only outputs textual data in the server's encoding, it can declare that by setting OutputPluginOptions.output_mode to OUTPUT_PLUGIN_TEXTUAL_OUTPUT instead of OUTPUT_PLUGIN_BINARY_OUTPUT in the startup callback. In that case, all the data has to be in the server's encoding so that a text datum can contain it. This is checked in assertion-enabled builds. Output Plugin Callbacks An output plugin gets notified about changes that are happening via various callbacks it needs to provide. Concurrent transactions are decoded in commit order, and only changes belonging to a specific transaction are decoded between the begin and commit callbacks. Transactions that were rolled back explicitly or implicitly never get decoded. Successful savepoints are folded into the transaction containing them in the order they were executed within that transaction. Only transactions that have already safely been flushed to disk will be decoded. That can lead to a COMMIT not immediately being decoded in a directly following pg_logical_slot_get_changes() when synchronous_commit is set to off. Startup Callback The optional startup_cb callback is called whenever a replication slot is created or asked to stream changes, independent of the number of changes that are ready to be put out. typedef void (*LogicalDecodeStartupCB) ( struct LogicalDecodingContext *ctx, OutputPluginOptions *options, bool is_init ); The is_init parameter will be true when the replication slot is being created and false otherwise. options points to a struct of options that output plugins can set: typedef struct OutputPluginOptions { OutputPluginOutputType output_type; } OutputPluginOptions; output_type has to either be set to OUTPUT_PLUGIN_TEXTUAL_OUTPUT or OUTPUT_PLUGIN_BINARY_OUTPUT. See also . The startup callback should validate the options present in ctx->output_plugin_options. If the output plugin needs to have a state, it can use ctx->output_plugin_private to store it. Shutdown Callback The optional shutdown_cb callback is called whenever a formerly active replication slot is not used anymore and can be used to deallocate resources private to the output plugin. The slot isn't necessarily being dropped, streaming is just being stopped. typedef void (*LogicalDecodeShutdownCB) ( struct LogicalDecodingContext *ctx ); Transaction Begin Callback The required begin_cb callback is called whenever a start of a committed transaction has been decoded. Aborted transactions and their contents never get decoded. typedef void (*LogicalDecodeBeginCB) ( struct LogicalDecodingContext *, ReorderBufferTXN *txn ); The txn parameter contains meta information about the transaction, like the time stamp at which it has been committed and its XID. Transaction End Callback The required commit_cb callback is called whenever a transaction commit has been decoded. The change_cb callbacks for all modified rows will have been called before this, if there have been any modified rows. typedef void (*LogicalDecodeCommitCB) ( struct LogicalDecodingContext *, ReorderBufferTXN *txn ); Change Callback The required change_cb callback is called for every individual row modification inside a transaction, may it be an INSERT, UPDATE, or DELETE. Even if the original command modified several rows at once the callback will be called individually for each row. typedef void (*LogicalDecodeChangeCB) ( struct LogicalDecodingContext *ctx, ReorderBufferTXN *txn, Relation relation, ReorderBufferChange *change ); The ctx and txn parameters have the same contents as for the begin_cb and commit_cb callbacks, but additionally the relation descriptor relation points to the relation the row belongs to and a struct change describing the row modification are passed in. Only changes in user defined tables that are not unlogged (see ) and not temporary (see ) can be extracted using logical decoding. Origin Filter Callback The optional filter_by_origin_cb callback is called to determine whether data that has been replayed from origin_id is of interest to the output plugin. typedef bool (*LogicalDecodeFilterByOriginCB) ( struct LogicalDecodingContext *ctx, RepNodeId origin_id ); The ctx parameter has the same contents as for the other callbacks. No information but the origin is available. To signal that changes originating on the passed in node are irrelevant, return true, causing them to be filtered away; false otherwise. The other callbacks will not be called for transactions and changes that have been filtered away. This is useful when implementing cascading or multidirectional replication solutions. Filtering by the origin allows to prevent replicating the same changes back and forth in such setups. While transactions and changes also carry information about the origin, filtering via this callback is noticeably more efficient. Generic Message Callback The optional message_cb callback is called whenever a logical decoding message has been decoded. typedef void (*LogicalDecodeMessageCB) ( struct LogicalDecodingContext *, ReorderBufferTXN *txn, XLogRecPtr message_lsn, bool transactional, const char *prefix, Size message_size, const char *message ); The txn parameter contains meta information about the transaction, like the time stamp at which it has been committed and its XID. Note however that it can be NULL when the message is non-transactional and the XID was not assigned yet in the transaction which logged the message. The lsn has WAL position of the message. The transactional says if the message was sent as transactional or not. The prefix is arbitrary null-terminated prefix which can be used for identifying interesting messages for the current plugin. And finally the message parameter holds the actual message of message_size size. Extra care should be taken to ensure that the prefix the output plugin considers interesting is unique. Using name of the extension or the output plugin itself is often a good choice. Functions for Producing Output To actually produce output, output plugins can write data to the StringInfo output buffer in ctx->out when inside the begin_cb, commit_cb, or change_cb callbacks. Before writing to the output buffer, OutputPluginPrepareWrite(ctx, last_write) has to be called, and after finishing writing to the buffer, OutputPluginWrite(ctx, last_write) has to be called to perform the write. The last_write indicates whether a particular write was the callback's last write. The following example shows how to output data to the consumer of an output plugin: OutputPluginPrepareWrite(ctx, true); appendStringInfo(ctx->out, "BEGIN %u", txn->xid); OutputPluginWrite(ctx, true); Logical Decoding Output Writers It is possible to add more output methods for logical decoding. For details, see src/backend/replication/logical/logicalfuncs.c. Essentially, three functions need to be provided: one to read WAL, one to prepare writing output, and one to write the output (see ). Synchronous Replication Support for Logical Decoding Logical decoding can be used to build synchronous replication solutions with the same user interface as synchronous replication for streaming replication. To do this, the streaming replication interface (see ) must be used to stream out data. Clients have to send Standby status update (F) (see ) messages, just like streaming replication clients do. A synchronous replica receiving changes via logical decoding will work in the scope of a single database. Since, in contrast to that, synchronous_standby_names currently is server wide, this means this technique will not work properly if more than one database is actively used.