diff --git a/contrib/pg_walinspect/Makefile b/contrib/pg_walinspect/Makefile index 960530eb6c..7033878a79 100644 --- a/contrib/pg_walinspect/Makefile +++ b/contrib/pg_walinspect/Makefile @@ -7,7 +7,7 @@ OBJS = \ PGFILEDESC = "pg_walinspect - functions to inspect contents of PostgreSQL Write-Ahead Log" EXTENSION = pg_walinspect -DATA = pg_walinspect--1.0.sql +DATA = pg_walinspect--1.0.sql pg_walinspect--1.0--1.1.sql REGRESS = pg_walinspect diff --git a/contrib/pg_walinspect/expected/pg_walinspect.out b/contrib/pg_walinspect/expected/pg_walinspect.out index a1ee743457..9bcb05354e 100644 --- a/contrib/pg_walinspect/expected/pg_walinspect.out +++ b/contrib/pg_walinspect/expected/pg_walinspect.out @@ -10,7 +10,7 @@ CREATE TABLE sample_tbl(col1 int, col2 int); SELECT pg_current_wal_lsn() AS wal_lsn1 \gset INSERT INTO sample_tbl SELECT * FROM generate_series(1, 2); SELECT pg_current_wal_lsn() AS wal_lsn2 \gset -INSERT INTO sample_tbl SELECT * FROM generate_series(1, 2); +INSERT INTO sample_tbl SELECT * FROM generate_series(3, 4); -- =================================================================== -- Tests for input validation -- =================================================================== @@ -73,6 +73,23 @@ SELECT COUNT(*) >= 1 AS ok FROM pg_get_wal_records_info(:'wal_lsn1', :'wal_lsn2' t (1 row) +-- =================================================================== +-- Tests to get full page image (FPI) from WAL record +-- =================================================================== +SELECT pg_current_wal_lsn() AS wal_lsn3 \gset +-- Force FPI on the next update. +CHECKPOINT; +-- Update table to generate an FPI. +UPDATE sample_tbl SET col1 = col1 * 100 WHERE col1 = 1; +SELECT pg_current_wal_lsn() AS wal_lsn4 \gset +-- Check if we get FPI from WAL record. +SELECT COUNT(*) >= 1 AS ok FROM pg_get_wal_fpi_info(:'wal_lsn3', :'wal_lsn4') + WHERE relfilenode = :'sample_tbl_oid'; + ok +---- + t +(1 row) + -- =================================================================== -- Tests for permissions -- =================================================================== @@ -98,6 +115,13 @@ SELECT has_function_privilege('regress_pg_walinspect', f (1 row) +SELECT has_function_privilege('regress_pg_walinspect', + 'pg_get_wal_fpi_info(pg_lsn, pg_lsn) ', 'EXECUTE'); -- no + has_function_privilege +------------------------ + f +(1 row) + -- Functions accessible by users with role pg_read_server_files GRANT pg_read_server_files TO regress_pg_walinspect; SELECT has_function_privilege('regress_pg_walinspect', @@ -121,6 +145,13 @@ SELECT has_function_privilege('regress_pg_walinspect', t (1 row) +SELECT has_function_privilege('regress_pg_walinspect', + 'pg_get_wal_fpi_info(pg_lsn, pg_lsn) ', 'EXECUTE'); -- yes + has_function_privilege +------------------------ + t +(1 row) + REVOKE pg_read_server_files FROM regress_pg_walinspect; -- Superuser can grant execute to other users GRANT EXECUTE ON FUNCTION pg_get_wal_record_info(pg_lsn) @@ -129,6 +160,8 @@ GRANT EXECUTE ON FUNCTION pg_get_wal_records_info(pg_lsn, pg_lsn) TO regress_pg_walinspect; GRANT EXECUTE ON FUNCTION pg_get_wal_stats(pg_lsn, pg_lsn, boolean) TO regress_pg_walinspect; +GRANT EXECUTE ON FUNCTION pg_get_wal_fpi_info(pg_lsn, pg_lsn) + TO regress_pg_walinspect; SELECT has_function_privilege('regress_pg_walinspect', 'pg_get_wal_record_info(pg_lsn)', 'EXECUTE'); -- yes has_function_privilege @@ -150,12 +183,21 @@ SELECT has_function_privilege('regress_pg_walinspect', t (1 row) +SELECT has_function_privilege('regress_pg_walinspect', + 'pg_get_wal_fpi_info(pg_lsn, pg_lsn) ', 'EXECUTE'); -- yes + has_function_privilege +------------------------ + t +(1 row) + REVOKE EXECUTE ON FUNCTION pg_get_wal_record_info(pg_lsn) FROM regress_pg_walinspect; REVOKE EXECUTE ON FUNCTION pg_get_wal_records_info(pg_lsn, pg_lsn) FROM regress_pg_walinspect; REVOKE EXECUTE ON FUNCTION pg_get_wal_stats(pg_lsn, pg_lsn, boolean) FROM regress_pg_walinspect; +REVOKE EXECUTE ON FUNCTION pg_get_wal_fpi_info(pg_lsn, pg_lsn) + FROM regress_pg_walinspect; -- =================================================================== -- Clean up -- =================================================================== diff --git a/contrib/pg_walinspect/meson.build b/contrib/pg_walinspect/meson.build index f6e912a7d8..bf7b79b1b7 100644 --- a/contrib/pg_walinspect/meson.build +++ b/contrib/pg_walinspect/meson.build @@ -19,6 +19,7 @@ contrib_targets += pg_walinspect install_data( 'pg_walinspect.control', 'pg_walinspect--1.0.sql', + 'pg_walinspect--1.0--1.1.sql', kwargs: contrib_data_args, ) diff --git a/contrib/pg_walinspect/pg_walinspect--1.0--1.1.sql b/contrib/pg_walinspect/pg_walinspect--1.0--1.1.sql new file mode 100644 index 0000000000..1e9e1e6115 --- /dev/null +++ b/contrib/pg_walinspect/pg_walinspect--1.0--1.1.sql @@ -0,0 +1,24 @@ +/* contrib/pg_walinspect/pg_walinspect--1.0--1.1.sql */ + +-- complain if script is sourced in psql, rather than via ALTER EXTENSION +\echo Use "ALTER EXTENSION pg_walinspect UPDATE TO '1.1'" to load this file. \quit + +-- +-- pg_get_wal_fpi_info() +-- +CREATE FUNCTION pg_get_wal_fpi_info(IN start_lsn pg_lsn, + IN end_lsn pg_lsn, + OUT lsn pg_lsn, + OUT reltablespace oid, + OUT reldatabase oid, + OUT relfilenode oid, + OUT relblocknumber int8, + OUT forkname text, + OUT fpi bytea +) +RETURNS SETOF record +AS 'MODULE_PATHNAME', 'pg_get_wal_fpi_info' +LANGUAGE C STRICT PARALLEL SAFE; + +REVOKE EXECUTE ON FUNCTION pg_get_wal_fpi_info(pg_lsn, pg_lsn) FROM PUBLIC; +GRANT EXECUTE ON FUNCTION pg_get_wal_fpi_info(pg_lsn, pg_lsn) TO pg_read_server_files; diff --git a/contrib/pg_walinspect/pg_walinspect.c b/contrib/pg_walinspect/pg_walinspect.c index 08a4c2fb52..91b740ed27 100644 --- a/contrib/pg_walinspect/pg_walinspect.c +++ b/contrib/pg_walinspect/pg_walinspect.c @@ -30,6 +30,7 @@ PG_MODULE_MAGIC; +PG_FUNCTION_INFO_V1(pg_get_wal_fpi_info); PG_FUNCTION_INFO_V1(pg_get_wal_record_info); PG_FUNCTION_INFO_V1(pg_get_wal_records_info); PG_FUNCTION_INFO_V1(pg_get_wal_records_info_till_end_of_wal); @@ -55,6 +56,7 @@ static void FillXLogStatsRow(const char *name, uint64 n, uint64 total_count, Datum *values, bool *nulls, uint32 ncols); static void GetWalStats(FunctionCallInfo fcinfo, XLogRecPtr start_lsn, XLogRecPtr end_lsn, bool stats_per_record); +static void GetWALFPIInfo(FunctionCallInfo fcinfo, XLogReaderState *record); /* * Check if the given LSN is in future. Also, return the LSN up to which the @@ -217,6 +219,115 @@ GetWALRecordInfo(XLogReaderState *record, Datum *values, Assert(i == ncols); } + +/* + * Store a set of full page images from a single record. + */ +static void +GetWALFPIInfo(FunctionCallInfo fcinfo, XLogReaderState *record) +{ +#define PG_GET_WAL_FPI_INFO_COLS 7 + int block_id; + ReturnSetInfo *rsinfo = (ReturnSetInfo *) fcinfo->resultinfo; + + for (block_id = 0; block_id <= XLogRecMaxBlockId(record); block_id++) + { + PGAlignedBlock buf; + Page page; + bytea *raw_page; + BlockNumber blk; + RelFileLocator rnode; + ForkNumber fork; + Datum values[PG_GET_WAL_FPI_INFO_COLS] = {0}; + bool nulls[PG_GET_WAL_FPI_INFO_COLS] = {0}; + int i = 0; + + if (!XLogRecHasBlockRef(record, block_id)) + continue; + + if (!XLogRecHasBlockImage(record, block_id)) + continue; + + page = (Page) buf.data; + + if (!RestoreBlockImage(record, block_id, page)) + ereport(ERROR, + (errcode(ERRCODE_INTERNAL_ERROR), + errmsg_internal("%s", record->errormsg_buf))); + + /* Full page exists, so let's save it. */ + (void) XLogRecGetBlockTagExtended(record, block_id, + &rnode, &fork, &blk, NULL); + + values[i++] = LSNGetDatum(record->ReadRecPtr); + values[i++] = ObjectIdGetDatum(rnode.spcOid); + values[i++] = ObjectIdGetDatum(rnode.dbOid); + values[i++] = ObjectIdGetDatum(rnode.relNumber); + values[i++] = Int64GetDatum((int64) blk); + + if (fork >= 0 && fork <= MAX_FORKNUM) + values[i++] = CStringGetTextDatum(forkNames[fork]); + else + ereport(ERROR, + (errcode(ERRCODE_INTERNAL_ERROR), + errmsg_internal("invalid fork number: %u", fork))); + + /* Initialize bytea buffer to copy the FPI to. */ + raw_page = (bytea *) palloc(BLCKSZ + VARHDRSZ); + SET_VARSIZE(raw_page, BLCKSZ + VARHDRSZ); + + /* Take a verbatim copy of the FPI. */ + memcpy(VARDATA(raw_page), page, BLCKSZ); + + values[i++] = PointerGetDatum(raw_page); + + Assert(i == PG_GET_WAL_FPI_INFO_COLS); + + tuplestore_putvalues(rsinfo->setResult, rsinfo->setDesc, + values, nulls); + } + +#undef PG_GET_WAL_FPI_INFO_COLS +} + +/* + * Get full page images with their relation information for all the WAL + * records between start and end LSNs. Decompression is applied to the + * blocks, if necessary. + * + * This function emits an error if a future start or end WAL LSN i.e. WAL LSN + * the database system doesn't know about is specified. + */ +Datum +pg_get_wal_fpi_info(PG_FUNCTION_ARGS) +{ + XLogRecPtr start_lsn; + XLogRecPtr end_lsn; + XLogReaderState *xlogreader; + + start_lsn = PG_GETARG_LSN(0); + end_lsn = PG_GETARG_LSN(1); + + end_lsn = ValidateInputLSNs(false, start_lsn, end_lsn); + + InitMaterializedSRF(fcinfo, 0); + + xlogreader = InitXLogReaderState(start_lsn); + + while (ReadNextXLogRecord(xlogreader) && + xlogreader->EndRecPtr <= end_lsn) + { + GetWALFPIInfo(fcinfo, xlogreader); + + CHECK_FOR_INTERRUPTS(); + } + + pfree(xlogreader->private_data); + XLogReaderFree(xlogreader); + + PG_RETURN_VOID(); +} + /* * Get WAL record info. * diff --git a/contrib/pg_walinspect/pg_walinspect.control b/contrib/pg_walinspect/pg_walinspect.control index 017e56a2bb..efa3cb2cfe 100644 --- a/contrib/pg_walinspect/pg_walinspect.control +++ b/contrib/pg_walinspect/pg_walinspect.control @@ -1,5 +1,5 @@ # pg_walinspect extension comment = 'functions to inspect contents of PostgreSQL Write-Ahead Log' -default_version = '1.0' +default_version = '1.1' module_pathname = '$libdir/pg_walinspect' relocatable = true diff --git a/contrib/pg_walinspect/sql/pg_walinspect.sql b/contrib/pg_walinspect/sql/pg_walinspect.sql index 1b265ea7bc..849201a1f8 100644 --- a/contrib/pg_walinspect/sql/pg_walinspect.sql +++ b/contrib/pg_walinspect/sql/pg_walinspect.sql @@ -11,7 +11,7 @@ INSERT INTO sample_tbl SELECT * FROM generate_series(1, 2); SELECT pg_current_wal_lsn() AS wal_lsn2 \gset -INSERT INTO sample_tbl SELECT * FROM generate_series(1, 2); +INSERT INTO sample_tbl SELECT * FROM generate_series(3, 4); -- =================================================================== -- Tests for input validation @@ -52,6 +52,22 @@ SELECT COUNT(*) >= 1 AS ok FROM pg_get_wal_records_info(:'wal_lsn1', :'wal_lsn2' SELECT COUNT(*) >= 1 AS ok FROM pg_get_wal_records_info(:'wal_lsn1', :'wal_lsn2') WHERE resource_manager = 'Heap' AND record_type = 'INSERT'; +-- =================================================================== +-- Tests to get full page image (FPI) from WAL record +-- =================================================================== +SELECT pg_current_wal_lsn() AS wal_lsn3 \gset + +-- Force FPI on the next update. +CHECKPOINT; + +-- Update table to generate an FPI. +UPDATE sample_tbl SET col1 = col1 * 100 WHERE col1 = 1; +SELECT pg_current_wal_lsn() AS wal_lsn4 \gset + +-- Check if we get FPI from WAL record. +SELECT COUNT(*) >= 1 AS ok FROM pg_get_wal_fpi_info(:'wal_lsn3', :'wal_lsn4') + WHERE relfilenode = :'sample_tbl_oid'; + -- =================================================================== -- Tests for permissions -- =================================================================== @@ -66,6 +82,9 @@ SELECT has_function_privilege('regress_pg_walinspect', SELECT has_function_privilege('regress_pg_walinspect', 'pg_get_wal_stats(pg_lsn, pg_lsn, boolean) ', 'EXECUTE'); -- no +SELECT has_function_privilege('regress_pg_walinspect', + 'pg_get_wal_fpi_info(pg_lsn, pg_lsn) ', 'EXECUTE'); -- no + -- Functions accessible by users with role pg_read_server_files GRANT pg_read_server_files TO regress_pg_walinspect; @@ -79,6 +98,9 @@ SELECT has_function_privilege('regress_pg_walinspect', SELECT has_function_privilege('regress_pg_walinspect', 'pg_get_wal_stats(pg_lsn, pg_lsn, boolean) ', 'EXECUTE'); -- yes +SELECT has_function_privilege('regress_pg_walinspect', + 'pg_get_wal_fpi_info(pg_lsn, pg_lsn) ', 'EXECUTE'); -- yes + REVOKE pg_read_server_files FROM regress_pg_walinspect; -- Superuser can grant execute to other users @@ -91,6 +113,9 @@ GRANT EXECUTE ON FUNCTION pg_get_wal_records_info(pg_lsn, pg_lsn) GRANT EXECUTE ON FUNCTION pg_get_wal_stats(pg_lsn, pg_lsn, boolean) TO regress_pg_walinspect; +GRANT EXECUTE ON FUNCTION pg_get_wal_fpi_info(pg_lsn, pg_lsn) + TO regress_pg_walinspect; + SELECT has_function_privilege('regress_pg_walinspect', 'pg_get_wal_record_info(pg_lsn)', 'EXECUTE'); -- yes @@ -100,6 +125,9 @@ SELECT has_function_privilege('regress_pg_walinspect', SELECT has_function_privilege('regress_pg_walinspect', 'pg_get_wal_stats(pg_lsn, pg_lsn, boolean) ', 'EXECUTE'); -- yes +SELECT has_function_privilege('regress_pg_walinspect', + 'pg_get_wal_fpi_info(pg_lsn, pg_lsn) ', 'EXECUTE'); -- yes + REVOKE EXECUTE ON FUNCTION pg_get_wal_record_info(pg_lsn) FROM regress_pg_walinspect; @@ -109,6 +137,9 @@ REVOKE EXECUTE ON FUNCTION pg_get_wal_records_info(pg_lsn, pg_lsn) REVOKE EXECUTE ON FUNCTION pg_get_wal_stats(pg_lsn, pg_lsn, boolean) FROM regress_pg_walinspect; +REVOKE EXECUTE ON FUNCTION pg_get_wal_fpi_info(pg_lsn, pg_lsn) + FROM regress_pg_walinspect; + -- =================================================================== -- Clean up -- =================================================================== diff --git a/doc/src/sgml/pgwalinspect.sgml b/doc/src/sgml/pgwalinspect.sgml index 119e162e60..22677e54f2 100644 --- a/doc/src/sgml/pgwalinspect.sgml +++ b/doc/src/sgml/pgwalinspect.sgml @@ -188,6 +188,38 @@ combined_size_percentage | 2.8634072910530795 + + + pg_get_wal_fpi_info(start_lsn pg_lsn, end_lsn pg_lsn) returns setof record + + + + + Gets a copy of full page images as bytea values (after + applying decompression when necessary) and their information associated + with all the valid WAL records between + start_lsn and + end_lsn. Returns one row per full page image. + If start_lsn or + end_lsn are not yet available, the function + will raise an error. For example: + +postgres=# SELECT lsn, reltablespace, reldatabase, relfilenode, relblocknumber, + forkname, substring(fpi for 24) as fpi_trimmed + FROM pg_get_wal_fpi_info('0/1801690', '0/1825C60'); +-[ RECORD 1 ]--+--------------------------------------------------- +lsn | 0/1807E20 +reltablespace | 1663 +reldatabase | 5 +relfilenode | 16396 +relblocknumber | 43 +forkname | main +fpi_trimmed | \x00000000b89e660100000000a003c0030020042000000000 + + + + +