Add show_data option to pg_get_wal_block_info.

Allow users to opt out of returning FPI data and block data from
pg_get_wal_block_info as an optimization.  Testing has shown that this
can make function execution over twice as fast in some cases.

When pg_get_wal_block_info is called with "show_data := false", it
always returns NULL values for its block_data and block_fpi_data bytea
output parameters.  Nothing else changes.  In particular, the function
will still return the usual per-block summary of block data/FPI space
overhead.  Use of "show_data := false" is therefore feasible with all
queries that don't specifically require these raw binary strings.

Follow-up to recent work in commit 122376f0.  There still hasn't been a
stable release with the pg_get_wal_block_info function, so no bump in
the pg_walinspect extension version.

Per suggestion from Melanie Plageman.

Author: Peter Geoghegan <pg@bowt.ie>
Discussion: https://postgr.es/m/CAAKRu_bJvbcYBRj2cN6G2xV7B7-Ja+pjTO1nEnEhRR8OXYiABA@mail.gmail.com
Discussion: https://postgr.es/m/CAH2-Wzm9shOkEDM10_+qOZkRSQhKVxwBFiehH6EHWQQRd_rDPw@mail.gmail.com
This commit is contained in:
Peter Geoghegan 2023-03-31 14:02:52 -07:00
parent 6ee30209a6
commit df4f3ab517
6 changed files with 39 additions and 24 deletions

View File

@ -50,10 +50,10 @@ ERROR: WAL start LSN must be less than current LSN
ALTER EXTENSION pg_walinspect UPDATE TO '1.1';
-- List what version 1.1 contains.
\dx+ pg_walinspect
Objects in extension "pg_walinspect"
Object description
--------------------------------------------------
function pg_get_wal_block_info(pg_lsn,pg_lsn)
Objects in extension "pg_walinspect"
Object description
-------------------------------------------------------
function pg_get_wal_block_info(pg_lsn,pg_lsn,boolean)
function pg_get_wal_record_info(pg_lsn)
function pg_get_wal_records_info(pg_lsn,pg_lsn)
function pg_get_wal_stats(pg_lsn,pg_lsn,boolean)

View File

@ -166,7 +166,7 @@ SELECT has_function_privilege('regress_pg_walinspect',
(1 row)
SELECT has_function_privilege('regress_pg_walinspect',
'pg_get_wal_block_info(pg_lsn, pg_lsn) ', 'EXECUTE'); -- no
'pg_get_wal_block_info(pg_lsn, pg_lsn, boolean) ', 'EXECUTE'); -- no
has_function_privilege
------------------------
f
@ -196,7 +196,7 @@ SELECT has_function_privilege('regress_pg_walinspect',
(1 row)
SELECT has_function_privilege('regress_pg_walinspect',
'pg_get_wal_block_info(pg_lsn, pg_lsn) ', 'EXECUTE'); -- yes
'pg_get_wal_block_info(pg_lsn, pg_lsn, boolean) ', 'EXECUTE'); -- yes
has_function_privilege
------------------------
t
@ -210,7 +210,7 @@ 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_block_info(pg_lsn, pg_lsn)
GRANT EXECUTE ON FUNCTION pg_get_wal_block_info(pg_lsn, pg_lsn, boolean)
TO regress_pg_walinspect;
SELECT has_function_privilege('regress_pg_walinspect',
'pg_get_wal_record_info(pg_lsn)', 'EXECUTE'); -- yes
@ -234,7 +234,7 @@ SELECT has_function_privilege('regress_pg_walinspect',
(1 row)
SELECT has_function_privilege('regress_pg_walinspect',
'pg_get_wal_block_info(pg_lsn, pg_lsn) ', 'EXECUTE'); -- yes
'pg_get_wal_block_info(pg_lsn, pg_lsn, boolean) ', 'EXECUTE'); -- yes
has_function_privilege
------------------------
t
@ -246,7 +246,7 @@ 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_block_info(pg_lsn, pg_lsn)
REVOKE EXECUTE ON FUNCTION pg_get_wal_block_info(pg_lsn, pg_lsn, boolean)
FROM regress_pg_walinspect;
-- ===================================================================
-- Clean up

View File

@ -12,6 +12,7 @@ DROP FUNCTION pg_get_wal_stats_till_end_of_wal(pg_lsn, boolean);
--
CREATE FUNCTION pg_get_wal_block_info(IN start_lsn pg_lsn,
IN end_lsn pg_lsn,
IN show_data boolean DEFAULT true,
OUT start_lsn pg_lsn,
OUT end_lsn pg_lsn,
OUT prev_lsn pg_lsn,
@ -37,5 +38,5 @@ RETURNS SETOF record
AS 'MODULE_PATHNAME', 'pg_get_wal_block_info'
LANGUAGE C STRICT PARALLEL SAFE;
REVOKE EXECUTE ON FUNCTION pg_get_wal_block_info(pg_lsn, pg_lsn) FROM PUBLIC;
GRANT EXECUTE ON FUNCTION pg_get_wal_block_info(pg_lsn, pg_lsn) TO pg_read_server_files;
REVOKE EXECUTE ON FUNCTION pg_get_wal_block_info(pg_lsn, pg_lsn, boolean) FROM PUBLIC;
GRANT EXECUTE ON FUNCTION pg_get_wal_block_info(pg_lsn, pg_lsn, boolean) TO pg_read_server_files;

View File

@ -59,7 +59,8 @@ static void GetWalStats(FunctionCallInfo fcinfo,
XLogRecPtr start_lsn,
XLogRecPtr end_lsn,
bool stats_per_record);
static void GetWALBlockInfo(FunctionCallInfo fcinfo, XLogReaderState *record);
static void GetWALBlockInfo(FunctionCallInfo fcinfo, XLogReaderState *record,
bool show_data);
/*
* Return the LSN up to which the server has WAL.
@ -244,7 +245,8 @@ GetWALRecordInfo(XLogReaderState *record, Datum *values,
* Keep this in sync with GetWALRecordInfo.
*/
static void
GetWALBlockInfo(FunctionCallInfo fcinfo, XLogReaderState *record)
GetWALBlockInfo(FunctionCallInfo fcinfo, XLogReaderState *record,
bool show_data)
{
#define PG_GET_WAL_BLOCK_INFO_COLS 20
int block_id;
@ -359,7 +361,7 @@ GetWALBlockInfo(FunctionCallInfo fcinfo, XLogReaderState *record)
nulls[i++] = true;
/* block_data output */
if (blk->has_data)
if (blk->has_data && show_data)
{
bytea *block_data;
@ -372,7 +374,7 @@ GetWALBlockInfo(FunctionCallInfo fcinfo, XLogReaderState *record)
nulls[i++] = true;
/* block_fpi_data output */
if (blk->has_image)
if (blk->has_image && show_data)
{
PGAlignedBlock buf;
Page page;
@ -410,6 +412,7 @@ pg_get_wal_block_info(PG_FUNCTION_ARGS)
{
XLogRecPtr start_lsn = PG_GETARG_LSN(0);
XLogRecPtr end_lsn = PG_GETARG_LSN(1);
bool show_data = PG_GETARG_BOOL(2);
XLogReaderState *xlogreader;
MemoryContext old_cxt;
MemoryContext tmp_cxt;
@ -435,7 +438,7 @@ pg_get_wal_block_info(PG_FUNCTION_ARGS)
/* Use the tmp context so we can clean up after each tuple is done */
old_cxt = MemoryContextSwitchTo(tmp_cxt);
GetWALBlockInfo(fcinfo, xlogreader);
GetWALBlockInfo(fcinfo, xlogreader, show_data);
/* clean up and switch back */
MemoryContextSwitchTo(old_cxt);

View File

@ -101,7 +101,7 @@ 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_block_info(pg_lsn, pg_lsn) ', 'EXECUTE'); -- no
'pg_get_wal_block_info(pg_lsn, pg_lsn, boolean) ', 'EXECUTE'); -- no
-- Functions accessible by users with role pg_read_server_files.
GRANT pg_read_server_files TO regress_pg_walinspect;
@ -113,7 +113,7 @@ 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_block_info(pg_lsn, pg_lsn) ', 'EXECUTE'); -- yes
'pg_get_wal_block_info(pg_lsn, pg_lsn, boolean) ', 'EXECUTE'); -- yes
REVOKE pg_read_server_files FROM regress_pg_walinspect;
@ -124,7 +124,7 @@ 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_block_info(pg_lsn, pg_lsn)
GRANT EXECUTE ON FUNCTION pg_get_wal_block_info(pg_lsn, pg_lsn, boolean)
TO regress_pg_walinspect;
SELECT has_function_privilege('regress_pg_walinspect',
@ -134,7 +134,7 @@ 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_block_info(pg_lsn, pg_lsn) ', 'EXECUTE'); -- yes
'pg_get_wal_block_info(pg_lsn, pg_lsn, boolean) ', 'EXECUTE'); -- yes
REVOKE EXECUTE ON FUNCTION pg_get_wal_record_info(pg_lsn)
FROM regress_pg_walinspect;
@ -142,7 +142,7 @@ 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_block_info(pg_lsn, pg_lsn)
REVOKE EXECUTE ON FUNCTION pg_get_wal_block_info(pg_lsn, pg_lsn, boolean)
FROM regress_pg_walinspect;
-- ===================================================================

View File

@ -133,7 +133,7 @@ block_ref |
<varlistentry>
<term>
<function>pg_get_wal_block_info(start_lsn pg_lsn, end_lsn pg_lsn) returns setof record</function>
<function>pg_get_wal_block_info(start_lsn pg_lsn, end_lsn pg_lsn, show_data boolean DEFAULT true) returns setof record</function>
</term>
<listitem>
@ -209,10 +209,21 @@ block_fpi_data |
<para>
The <function>pg_filenode_relation</function> function (see
<xref linkend="functions-admin-dblocation"/>) can help you to
determine which block/relation was modified by each WAL record
during original execution
determine which relation was modified during original execution
</para>
</tip>
<para>
It is possible for clients to avoid the overhead of
materializing block data. This may make function execution
significantly faster. When <replaceable>show_data</replaceable>
is set to <literal>false</literal>, <structfield>block_data</structfield>
and <structfield>block_fpi_data</structfield> values are omitted
(that is, the <structfield>block_data</structfield> and
<structfield>block_fpi_data</structfield> <literal>OUT</literal>
arguments are <literal>NULL</literal> for all rows returned).
Obviously, this optimization is only feasible with queries where
block data isn't truly required.
</para>
<para>
The function raises an error if
<replaceable>start_lsn</replaceable> is not available.