Let plan_cache_mode to be a little less strict

Started by Andrei Lepikhov6 months ago8 messages
#1Andrei Lepikhov
lepihov@gmail.com
1 attachment(s)

Hi,

I believe the behaviour of the choose_custom_plan function should be
adjusted slightly.

The CachedPlanSource can operate in either auto mode or force a specific
plan type. Currently, the force_generic_plan option declares all plans
as generic, except one-shot plans, of course. However, the
CachedPlanSource entry also has a cursor_options field that indicates
the caller's anticipation of a specific plan type for the statement.
This means that the configuration parameter (GUC) currently overrides
any explicit request for a plan type. The documentation does not clearly
explain the rationale behind this, at least to me.
I propose that the declaration of cursor_options should take precedence
over the GUC. This change would alter the interpretation of the GUC from
a 'forced' plan type to a 'default' plan type. By making this
adjustment, users and extensions can be more assured that they will
receive the requested plan type.

If there are no objections, I will add this patch to the next commitfest.

--
regards, Andrei Lepikhov

Attachments:

v0-0001-Make-the-plan-cache-forced-modes-more-flexible.patchtext/plain; charset=UTF-8; name=v0-0001-Make-the-plan-cache-forced-modes-more-flexible.patchDownload
From 7dd2140fdbdd842f454ac631ca15ec80a2ea1cab Mon Sep 17 00:00:00 2001
From: "Andrei V. Lepikhov" <lepihov@gmail.com>
Date: Mon, 14 Jul 2025 16:25:59 +0200
Subject: [PATCH v0] Make the plan cache forced modes more flexible.

---
 src/backend/utils/cache/plancache.c | 12 ++++++------
 1 file changed, 6 insertions(+), 6 deletions(-)

diff --git a/src/backend/utils/cache/plancache.c b/src/backend/utils/cache/plancache.c
index 89a1c79e984..5b357299683 100644
--- a/src/backend/utils/cache/plancache.c
+++ b/src/backend/utils/cache/plancache.c
@@ -1170,18 +1170,18 @@ choose_custom_plan(CachedPlanSource *plansource, ParamListInfo boundParams)
 	if (!StmtPlanRequiresRevalidation(plansource))
 		return false;
 
-	/* Let settings force the decision */
-	if (plan_cache_mode == PLAN_CACHE_MODE_FORCE_GENERIC_PLAN)
-		return false;
-	if (plan_cache_mode == PLAN_CACHE_MODE_FORCE_CUSTOM_PLAN)
-		return true;
-
 	/* See if caller wants to force the decision */
 	if (plansource->cursor_options & CURSOR_OPT_GENERIC_PLAN)
 		return false;
 	if (plansource->cursor_options & CURSOR_OPT_CUSTOM_PLAN)
 		return true;
 
+	/* Let settings force the decision */
+	if (plan_cache_mode == PLAN_CACHE_MODE_FORCE_GENERIC_PLAN)
+		return false;
+	if (plan_cache_mode == PLAN_CACHE_MODE_FORCE_CUSTOM_PLAN)
+		return true;
+
 	/* Generate custom plans until we have done at least 5 (arbitrary) */
 	if (plansource->num_custom_plans < 5)
 		return true;
-- 
2.50.1

#2Andy Fan
zhihuifan1213@163.com
In reply to: Andrei Lepikhov (#1)
Re: Let plan_cache_mode to be a little less strict

Andrei Lepikhov <lepihov@gmail.com> writes:

CachedPlanSource entry also has a cursor_options field that indicates
the caller's anticipation of a specific plan type for the statement.

..

I propose that the declaration of cursor_options should take precedence
over the GUC.

This Looks good to me.

--
Best Regards
Andy Fan

#3Sami Imseih
samimseih@gmail.com
In reply to: Andy Fan (#2)
Re: Let plan_cache_mode to be a little less strict

This means that the configuration parameter (GUC) currently overrides
any explicit request for a plan type. The documentation does not clearly
explain the rationale behind this, at least to me.

The documentation [0]https://www.postgresql.org/docs/current/spi-spi-prepare.html mentions " If this default behavior is
unsuitable, you can alter it by
passing the CURSOR_OPT_GENERIC_PLAN or CURSOR_OPT_CUSTOM_PLAN flag to
SPI_prepare_cursor". The default behavior here is plan_cache_mode = AUTO.

But the docs leave out the fact that is plan_cache_mode is not AUTO, that the
GUC settings take precedence over the cursor_options. I agree as well that is
wrong. I also agree with your fix.

[0]: https://www.postgresql.org/docs/current/spi-spi-prepare.html

--
Sami

#4Michael Paquier
michael@paquier.xyz
In reply to: Sami Imseih (#3)
Re: Let plan_cache_mode to be a little less strict

On Thu, Jul 31, 2025 at 11:52:59AM -0500, Sami Imseih wrote:

This means that the configuration parameter (GUC) currently overrides
any explicit request for a plan type. The documentation does not clearly
explain the rationale behind this, at least to me.

The documentation [0] mentions " If this default behavior is
unsuitable, you can alter it by
passing the CURSOR_OPT_GENERIC_PLAN or CURSOR_OPT_CUSTOM_PLAN flag to
SPI_prepare_cursor". The default behavior here is plan_cache_mode = AUTO.

But the docs leave out the fact that is plan_cache_mode is not AUTO, that the
GUC settings take precedence over the cursor_options. I agree as well that is
wrong. I also agree with your fix.

[0] https://www.postgresql.org/docs/current/spi-spi-prepare.html

It seems to me that if we want to keep track of the priority of the
GUC versus the options given to the SPI call, then we should at least
have some tests for this purpose. I would imagine a test module with
a set of SQL functions that act as wrappers of the SPI calls we want
to test, and arguments that can be given directly in input, using
PG_GETARG_POINTER and PG_RETURN_POINTER for some of them. We could
also have a function in regress.c, which may be simpler here. These
functions should be designed to be generic enough, so as they could be
reused for more tests than the ones we'd look at here.
--
Michael

#5Andrei Lepikhov
lepihov@gmail.com
In reply to: Michael Paquier (#4)
Re: Let plan_cache_mode to be a little less strict

On 1/8/2025 00:56, Michael Paquier wrote:

On Thu, Jul 31, 2025 at 11:52:59AM -0500, Sami Imseih wrote:

But the docs leave out the fact that is plan_cache_mode is not AUTO, that the
GUC settings take precedence over the cursor_options. I agree as well that is
wrong. I also agree with your fix.

[0] https://www.postgresql.org/docs/current/spi-spi-prepare.html

It seems to me that if we want to keep track of the priority of the
GUC versus the options given to the SPI call, then we should at least
have some tests for this purpose. I would imagine a test module with
a set of SQL functions that act as wrappers of the SPI calls we want
to test, and arguments that can be given directly in input, using
PG_GETARG_POINTER and PG_RETURN_POINTER for some of them. We could
also have a function in regress.c, which may be simpler here. These
functions should be designed to be generic enough, so as they could be
reused for more tests than the ones we'd look at here.

I considered the worker_spi.c module, which demonstrates various SPI
usage patterns. It might be more beneficial to use this instead of
creating another test module, isn't it?

--
regards, Andrei Lepikhov

#6Michael Paquier
michael@paquier.xyz
In reply to: Andrei Lepikhov (#5)
Re: Let plan_cache_mode to be a little less strict

On Fri, Aug 01, 2025 at 03:07:08PM +0200, Andrei Lepikhov wrote:

I considered the worker_spi.c module, which demonstrates various SPI usage
patterns. It might be more beneficial to use this instead of creating
another test module, isn't it?

worker_spi is a playground for bgworker tests, so I'm not eager to
make it more complex for the case of cached planned. SQL tests have
more benefits here, IMO, and they should be more efficient and more
predictible. worker_spi can only work with TAP.
--
Michael

#7Andrei Lepikhov
lepihov@gmail.com
In reply to: Michael Paquier (#4)
Re: Let plan_cache_mode to be a little less strict

On 1/8/2025 00:56, Michael Paquier wrote:

On Thu, Jul 31, 2025 at 11:52:59AM -0500, Sami Imseih wrote:

This means that the configuration parameter (GUC) currently overrides
any explicit request for a plan type. The documentation does not clearly
explain the rationale behind this, at least to me.

The documentation [0] mentions " If this default behavior is
unsuitable, you can alter it by
passing the CURSOR_OPT_GENERIC_PLAN or CURSOR_OPT_CUSTOM_PLAN flag to
SPI_prepare_cursor". The default behavior here is plan_cache_mode = AUTO.

But the docs leave out the fact that is plan_cache_mode is not AUTO, that the
GUC settings take precedence over the cursor_options. I agree as well that is
wrong. I also agree with your fix.

[0] https://www.postgresql.org/docs/current/spi-spi-prepare.html

It seems to me that if we want to keep track of the priority of the
GUC versus the options given to the SPI call, then we should at least
have some tests for this purpose. I would imagine a test module with
a set of SQL functions that act as wrappers of the SPI calls we want
to test, and arguments that can be given directly in input, using
PG_GETARG_POINTER and PG_RETURN_POINTER for some of them.

I'm not sure I understand it clearly. You propose to transfer some
internal data, let's say SPIPlanPtr, between different UDFs?
Reading the documentation, I see that SPI is intended to be used inside
a UDF. For example, the SPI_connect routine 'connect a C function to the
SPI manager'.
I am afraid that this mechanism is not ready to survive a function
context switch safely. Or do you mean it is ok to restrict test coverage
to only the 'saved' statements?

--
regards, Andrei Lepikhov

#8Andrei Lepikhov
lepihov@gmail.com
In reply to: Michael Paquier (#6)
1 attachment(s)
Re: Let plan_cache_mode to be a little less strict

On 4/8/2025 06:23, Michael Paquier wrote:

On Fri, Aug 01, 2025 at 03:07:08PM +0200, Andrei Lepikhov wrote:

I considered the worker_spi.c module, which demonstrates various SPI usage
patterns. It might be more beneficial to use this instead of creating
another test module, isn't it?

worker_spi is a playground for bgworker tests, so I'm not eager to
make it more complex for the case of cached planned. SQL tests have
more benefits here, IMO, and they should be more efficient and more
predictible. worker_spi can only work with TAP.

I began to implement the idea, described above and got stuck on the
issue that we can't explain an SPI plan. It is possible to invent an
'auto_explain' approach (as a TAP test, of course), but it looks wrong.
As an alternative, it is feasible to add to the SPI interface an
SPI_explain_plan routine using the analogy of ExplainExecuteQuery. I
recall hearing some requests for this kind of feature before. Is this a
commitable way?

See the patch attached. Do I understand correctly the 'SPI wrapper'
approach?

--
regards, Andrei Lepikhov

Attachments:

v0-0001-Basic-routines-for-testing-saved-SPI-plans.patchtext/plain; charset=UTF-8; name=v0-0001-Basic-routines-for-testing-saved-SPI-plans.patchDownload
From 0af47577ed00aae884b2cc11d10b1f058a896c2c Mon Sep 17 00:00:00 2001
From: "Andrei V. Lepikhov" <lepihov@gmail.com>
Date: Fri, 22 Aug 2025 13:39:04 +0200
Subject: [PATCH v0] Basic routines for testing saved SPI plans

---
 src/test/regress/expected/misc_functions.out |  12 ++
 src/test/regress/regress.c                   | 199 +++++++++++++++++++
 src/test/regress/sql/misc_functions.sql      |  15 ++
 src/test/regress/sql/plancache.sql           |  19 ++
 4 files changed, 245 insertions(+)

diff --git a/src/test/regress/expected/misc_functions.out b/src/test/regress/expected/misc_functions.out
index c3b2b9d8603..0ce8b37a769 100644
--- a/src/test/regress/expected/misc_functions.out
+++ b/src/test/regress/expected/misc_functions.out
@@ -914,6 +914,18 @@ SELECT test_relpath();
  
 (1 row)
 
+CREATE FUNCTION prepare_spi_plan(text, text, VARIADIC text[])
+RETURNS bigint
+    AS :'regresslib', 'prepare_spi_plan'
+    LANGUAGE C;
+CREATE FUNCTION execute_spi_plan(bigint, text, "any")
+RETURNS SETOF record
+    AS :'regresslib', 'execute_spi_plan'
+    LANGUAGE C STRICT;
+CREATE FUNCTION free_spi_plan(bigint)
+RETURNS void
+    AS :'regresslib', 'free_spi_plan'
+    LANGUAGE C STRICT;
 -- pg_replication_origin.roname limit
 SELECT pg_replication_origin_create('regress_' || repeat('a', 505));
 ERROR:  replication origin name is too long
diff --git a/src/test/regress/regress.c b/src/test/regress/regress.c
index 465ac148ac9..f19d544e601 100644
--- a/src/test/regress/regress.c
+++ b/src/test/regress/regress.c
@@ -42,9 +42,11 @@
 #include "utils/array.h"
 #include "utils/builtins.h"
 #include "utils/geo_decls.h"
+#include "utils/lsyscache.h"
 #include "utils/memutils.h"
 #include "utils/rel.h"
 #include "utils/typcache.h"
+#include "utils/varlena.h"
 
 #define EXPECT_TRUE(expr)	\
 	do { \
@@ -1028,3 +1030,200 @@ test_relpath(PG_FUNCTION_ARGS)
 
 	PG_RETURN_VOID();
 }
+
+static int
+setup_cursor_options(const char *options_string)
+{
+	List	   *optionLst = NIL;
+	ListCell   *lc;
+	int			cursorOptions = 0;
+
+	if (!SplitIdentifierString(pstrdup(options_string), ',', &optionLst))
+		/* syntax error in option list */
+		ereport(ERROR,
+				(errcode(ERRCODE_INVALID_PARAMETER_VALUE),
+				 errmsg("parameter \"%s\" must be a list of parameters",
+						"cursor_options")));
+
+	foreach(lc, optionLst)
+	{
+		const char *option = (const char *) lfirst(lc);
+
+		if (pg_strcasecmp(option, "fast_plan") == 0)
+			cursorOptions |= CURSOR_OPT_FAST_PLAN;
+		else if (pg_strcasecmp(option, "generic_plan") == 0)
+			cursorOptions |= CURSOR_OPT_GENERIC_PLAN;
+		else if (pg_strcasecmp(option, "custom_plan") == 0)
+			cursorOptions |= CURSOR_OPT_CUSTOM_PLAN;
+		else if (pg_strcasecmp(option, "parallel_ok") == 0)
+			cursorOptions |= CURSOR_OPT_PARALLEL_OK;
+		else
+			ereport(ERROR,
+				(errcode(ERRCODE_INVALID_PARAMETER_VALUE),
+				 errmsg("unknown cursor option %s", option)));
+	}
+
+	list_free(optionLst);
+	return cursorOptions;
+}
+
+ /*
+  * Prepare a plan cache entry for incoming parameterised query with specific
+  * set of cursor options.
+  *
+  * cursor_options string may contain any combination of the following values:
+  * 'fast_plan', 'generic_plan', 'custom_plan', or 'parallel_ok'.
+  *
+  * Returns internal pointer to saved SPI plan.
+  */
+PG_FUNCTION_INFO_V1(prepare_spi_plan);
+Datum
+prepare_spi_plan(PG_FUNCTION_ARGS)
+{
+	const char *query_text;
+	int			cursorOptions = 0;
+	ArrayType  *arr;
+	Datum	   *elements = NULL;
+	bool	   *nulls = NULL;
+	Oid			element_type = InvalidOid;
+	int16		elmlen;
+	bool		elmbyval;
+	char		elmalign;
+	int			nitems;
+	int			i;
+	Oid		   *argtypes;
+	SPIPlanPtr	result;
+
+	Assert(PG_NARGS() == 3 && get_fn_expr_variadic(fcinfo->flinfo));
+
+	/* Check supplied arguments */
+	if (PG_ARGISNULL(0))
+		ereport(ERROR,
+				(errcode(ERRCODE_INVALID_PARAMETER_VALUE),
+				 errmsg("query text cannot be null")));
+	query_text = text_to_cstring(PG_GETARG_TEXT_PP(0));
+	if (PG_ARGISNULL(2))
+		ereport(ERROR,
+				(errcode(ERRCODE_INVALID_PARAMETER_VALUE),
+				 errmsg("list of parameters canot be null")));
+
+	if (!PG_ARGISNULL(1))
+	{
+		char   *options = text_to_cstring(PG_GETARG_TEXT_PP(1));
+
+		cursorOptions = setup_cursor_options(options);
+	}
+
+	/* Prepare the Oid array of the query parameters */
+
+	arr = PG_GETARG_ARRAYTYPE_P(2);
+	element_type = ARR_ELEMTYPE(arr);
+	get_typlenbyvalalign(element_type, &elmlen, &elmbyval, &elmalign);
+
+	/* Extract all array elements */
+	deconstruct_array(arr, element_type, elmlen, elmbyval, elmalign,
+					  &elements, &nulls, &nitems);
+
+	argtypes = palloc(nitems * sizeof(Oid));
+	for (i = 0; i < nitems; i++)
+	{
+		const char *typname;
+
+		if (nulls[i])
+			ereport(ERROR,
+					(errcode(ERRCODE_INVALID_PARAMETER_VALUE),
+					 errmsg("type name cannot be NULL")));
+
+		typname = TextDatumGetCString(elements[i]);
+		argtypes[i] = DirectFunctionCall1Coll(regtypein,
+											  InvalidOid,
+											  CStringGetDatum(typname));
+	}
+
+	/* Create plancache entry and save the plan */
+	SPI_connect();
+	result = SPI_prepare_cursor(query_text, nitems, argtypes, cursorOptions);
+	result = SPI_saveplan(result);
+	SPI_finish();
+	PG_RETURN_POINTER(result);
+}
+
+PG_FUNCTION_INFO_V1(execute_spi_plan);
+Datum
+execute_spi_plan(PG_FUNCTION_ARGS)
+{
+	ReturnSetInfo  *rsinfo = (ReturnSetInfo *) fcinfo->resultinfo;
+	SPIPlanPtr		plan = (SPIPlanPtr) PG_GETARG_POINTER(0);
+	int				nargs = PG_NARGS();
+	Datum		   *values;
+	char		   *Nulls;
+	int				spirc;
+	int				i;
+
+	if (!SPI_plan_is_valid(plan))
+		PG_RETURN_NULL();
+
+	Assert(!get_fn_expr_variadic(fcinfo->flinfo));
+
+	/*
+	 * Caller wants to change cursor options. Update it for each statement.
+	 */
+	if (!PG_ARGISNULL(1))
+	{
+		char 	   *options = text_to_cstring(PG_GETARG_TEXT_PP(1));
+		List	   *plansources = SPI_plan_get_plan_sources(plan);
+		int			cursorOptions = 0;
+		ListCell   *lc;
+
+		cursorOptions = setup_cursor_options(options);
+
+		foreach(lc, plansources)
+		{
+			CachedPlanSource *src = lfirst(lc);
+
+			src->cursor_options = cursorOptions;
+		}
+	}
+
+	values = palloc((nargs - 2) * sizeof(Datum));
+	Nulls = palloc((nargs - 2) * sizeof(char *));
+	for (i = 2; i < nargs; i++)
+	{
+		if (!PG_ARGISNULL(i))
+		{
+			Nulls[i - 2] = ' ';
+			values[i - 2] = PG_GETARG_DATUM(i);
+		}
+		else
+			Nulls[i - 2] = 'n';
+	}
+
+	SPI_connect();
+	spirc = SPI_execute_plan(plan, values, Nulls, false, 0);
+	if (spirc <= 0)
+		elog(ERROR, "failed to execute the SPI plan %d", spirc);
+
+	rsinfo->expectedDesc = SPI_tuptable->tupdesc;
+	InitMaterializedSRF(fcinfo, MAT_SRF_USE_EXPECTED_DESC | MAT_SRF_BLESS);
+
+	for (i = 0; i < SPI_processed; i++)
+	{
+		tuplestore_puttuple(rsinfo->setResult, SPI_tuptable->vals[i]);
+	}
+
+	SPI_finish();
+
+	return (Datum) 0;
+}
+
+PG_FUNCTION_INFO_V1(free_spi_plan);
+Datum
+free_spi_plan(PG_FUNCTION_ARGS)
+{
+	SPIPlanPtr plan = (SPIPlanPtr) PG_GETARG_POINTER(0);
+
+	SPI_connect();
+	SPI_freeplan(plan);
+	SPI_finish();
+	PG_RETURN_VOID();
+}
diff --git a/src/test/regress/sql/misc_functions.sql b/src/test/regress/sql/misc_functions.sql
index 23792c4132a..8b2c69c51c4 100644
--- a/src/test/regress/sql/misc_functions.sql
+++ b/src/test/regress/sql/misc_functions.sql
@@ -412,5 +412,20 @@ CREATE FUNCTION test_relpath()
     LANGUAGE C;
 SELECT test_relpath();
 
+CREATE FUNCTION prepare_spi_plan(text, text, VARIADIC text[])
+RETURNS bigint
+    AS :'regresslib', 'prepare_spi_plan'
+    LANGUAGE C;
+
+CREATE FUNCTION execute_spi_plan(bigint, text, "any")
+RETURNS SETOF record
+    AS :'regresslib', 'execute_spi_plan'
+    LANGUAGE C STRICT;
+
+CREATE FUNCTION free_spi_plan(bigint)
+RETURNS void
+    AS :'regresslib', 'free_spi_plan'
+    LANGUAGE C STRICT;
+
 -- pg_replication_origin.roname limit
 SELECT pg_replication_origin_create('regress_' || repeat('a', 505));
diff --git a/src/test/regress/sql/plancache.sql b/src/test/regress/sql/plancache.sql
index 4b2f11dcc64..7b52a5ac343 100644
--- a/src/test/regress/sql/plancache.sql
+++ b/src/test/regress/sql/plancache.sql
@@ -223,3 +223,22 @@ select name, generic_plans, custom_plans from pg_prepared_statements
   where  name = 'test_mode_pp';
 
 drop table test_mode;
+
+-- Check the interference between plan_cache_mode and cursor_options
+-- EXPLAIN (COSTS OFF, GENERIC_PLAN)
+
+SELECT prepare_spi_plan(NULL, NULL, NULL); -- ERROR
+SELECT prepare_spi_plan(
+  'EXPLAIN (COSTS OFF) SELECT * FROM pcachetest WHERE q1 = $1',
+  NULL, 'integer') AS p1 \gset
+SELECT prepare_spi_plan(
+  'SELECT * FROM pcachetest WHERE q1 = $1 OR q1 = $2',
+  NULL, 'integer', NULL); --ERROR
+SELECT prepare_spi_plan(
+  'SELECT * FROM pcachetest WHERE q1 = $1 OR q1 = 3',
+  NULL, 'integer', 'numeric') AS p2 \gset
+
+SELECT execute_spi_plan(:p1, 'generic_plan', 42);
+
+SELECT free_spi_plan(:p1);
+SELECT free_spi_plan(:p2);
-- 
2.51.0