F.37. pg_walinspect — low-level WAL inspection #

F.37.1. General Functions
F.37.2. Author

The pg_walinspect module provides SQL functions that allow you to inspect the contents of write-ahead log of a running PostgreSQL database cluster at a low level, which is useful for debugging, analytical, reporting or educational purposes. It is similar to pg_waldump, but accessible through SQL rather than a separate utility.

All the functions of this module will provide the WAL information using the current server's timeline ID.

All the functions of this module will try to find the first valid WAL record that is at or after the given in_lsn or start_lsn and will emit error if no such record is available. Similarly, the end_lsn must be available, and if it falls in the middle of a record, the entire record must be available.

Note

Some functions, such as pg_logical_emit_message, return the LSN after the record just inserted. Therefore, if you pass that LSN as in_lsn or start_lsn to one of these functions, it will return the next record.

By default, use of these functions is restricted to superusers and members of the pg_read_server_files role. Access may be granted by superusers to others using GRANT.

F.37.1. General Functions #

pg_get_wal_record_info(in_lsn pg_lsn) returns record #

Gets WAL record information of a given LSN. If the given LSN isn't at the start of a WAL record, it gives the information of the next available valid WAL record; or an error if no such record is found. For example, usage of the function is as follows:

postgres=# SELECT * FROM pg_get_wal_record_info('0/1E826E98');
-[ RECORD 1 ]----+----------------------------------------------------
start_lsn        | 0/1E826F20
end_lsn          | 0/1E826F60
prev_lsn         | 0/1E826C80
xid              | 0
resource_manager | Heap2
record_type      | PRUNE
record_length    | 58
main_data_length | 8
fpi_length       | 0
description      | snapshotConflictHorizon 33748 nredirected 0 ndead 2
block_ref        | blkref #0: rel 1663/5/60221 fork main blk 2

pg_get_wal_records_info(start_lsn pg_lsn, end_lsn pg_lsn) returns setof record #

Gets information of all the valid WAL records between start_lsn and end_lsn. Returns one row per WAL record. If a future end_lsn (i.e. ahead of the current LSN of the server) is specified, it returns information until the end of WAL. The function raises an error if start_lsn is not available. For example, usage of the function is as follows:

postgres=# SELECT * FROM pg_get_wal_records_info('0/1E913618', '0/1E913740') LIMIT 1;
-[ RECORD 1 ]----+--------------------------------------------------------------
start_lsn        | 0/1E913618
end_lsn          | 0/1E913650
prev_lsn         | 0/1E9135A0
xid              | 0
resource_manager | Standby
record_type      | RUNNING_XACTS
record_length    | 50
main_data_length | 24
fpi_length       | 0
description      | nextXid 33775 latestCompletedXid 33774 oldestRunningXid 33775
block_ref        |

pg_get_wal_stats(start_lsn pg_lsn, end_lsn pg_lsn, per_record boolean DEFAULT false) returns setof record #

Gets statistics of all the valid WAL records between start_lsn and end_lsn. By default, it returns one row per resource_manager type. When per_record is set to true, it returns one row per record_type. If a future end_lsn (i.e. ahead of the current LSN of the server) is specified, it returns statistics until the end of WAL. An error is raised if start_lsn is not available. For example, usage of the function is as follows:

postgres=# SELECT * FROM pg_get_wal_stats('0/1E847D00', '0/1E84F500')
             WHERE count > 0 LIMIT 1 AND
                   "resource_manager/record_type" = 'Transaction';
-[ RECORD 1 ]----------------+-------------------
resource_manager/record_type | Transaction
count                        | 2
count_percentage             | 8
record_size                  | 875
record_size_percentage       | 41.23468426013195
fpi_size                     | 0
fpi_size_percentage          | 0
combined_size                | 875
combined_size_percentage     | 2.8634072910530795

pg_get_wal_block_info(start_lsn pg_lsn, end_lsn pg_lsn) returns setof record #

Gets a copy of the block information stored in WAL records. This includes copies of the block data (NULL if none) and full page images as bytea values (after applying decompression when necessary, or NULL if none) and their information associated with all the valid WAL records between start_lsn and end_lsn. Returns one row per block registered in a WAL record. If a future end_lsn (i.e. ahead of the current LSN of the server) is specified, it returns statistics until the end of WAL. An error is raised if start_lsn is not available. For example, usage of the function is as follows:

postgres=# SELECT lsn, blockid, reltablespace, reldatabase, relfilenode,
                  relblocknumber, forkname,
                  substring(blockdata for 24) as block_trimmed,
                  substring(fpi for 24) as fpi_trimmed, fpilen, fpiinfo
             FROM pg_get_wal_block_info('0/1871080', '0/1871440');
-[ RECORD 1 ]--+---------------------------------------------------
lsn            | 0/18712F8
blockid        | 0
reltablespace  | 1663
reldatabase    | 16384
relfilenode    | 16392
relblocknumber | 0
forkname       | main
block_trimmed  | \x02800128180164000000
fpi_trimmed    | \x0000000050108701000000002c00601f00200420e0020000
fpilen         | 204
fpiinfo        | {HAS_HOLE,APPLY}

F.37.2. Author #

Bharath Rupireddy