From bab4d858e18cdd50713ae430e28499ca2acab441 Mon Sep 17 00:00:00 2001 From: Julien Rouhaud Date: Wed, 24 Dec 2025 22:31:52 +0800 Subject: [PATCH v1] Cleanup explicit PREPARE query strings When a multi statements query string contains one PREPARE statement (or multiple), the whole query string was saved in the cached plan. This is wasteful as that string can be artitrarily big, but it can also confusing as some other parts like pg_prepared_statements will output the saved query string as-is. This commit changes this behavior and only stores the part of the query string that correspond to any given PREPARED statement, similarly to how it's already done in pg_stat_statements. --- contrib/auto_explain/t/001_auto_explain.pl | 8 ++-- src/backend/commands/prepare.c | 43 +++++++++++++++++++-- src/test/regress/expected/prepare.out | 44 +++++++++++++--------- src/test/regress/sql/prepare.sql | 2 +- 4 files changed, 72 insertions(+), 25 deletions(-) diff --git a/contrib/auto_explain/t/001_auto_explain.pl b/contrib/auto_explain/t/001_auto_explain.pl index 6af5ac1da18..535c4770095 100644 --- a/contrib/auto_explain/t/001_auto_explain.pl +++ b/contrib/auto_explain/t/001_auto_explain.pl @@ -60,7 +60,7 @@ $log_contents = query_log($node, like( $log_contents, - qr/Query Text: PREPARE get_proc\(name\) AS SELECT \* FROM pg_proc WHERE proname = \$1;/, + qr/Query Text: PREPARE get_proc\(name\) AS SELECT \* FROM pg_proc WHERE proname = \$1/, "prepared query text logged, text mode"); like( @@ -82,7 +82,7 @@ $log_contents = query_log( like( $log_contents, - qr/Query Text: PREPARE get_type\(name\) AS SELECT \* FROM pg_type WHERE typname = \$1;/, + qr/Query Text: PREPARE get_type\(name\) AS SELECT \* FROM pg_type WHERE typname = \$1/, "prepared query text logged, text mode"); like( @@ -98,7 +98,7 @@ $log_contents = query_log( like( $log_contents, - qr/Query Text: PREPARE get_type\(name\) AS SELECT \* FROM pg_type WHERE typname = \$1;/, + qr/Query Text: PREPARE get_type\(name\) AS SELECT \* FROM pg_type WHERE typname = \$1/, "prepared query text logged, text mode"); unlike( @@ -164,7 +164,7 @@ $log_contents = query_log( like( $log_contents, - qr/"Query Text": "PREPARE get_class\(name\) AS SELECT \* FROM pg_class WHERE relname = \$1;"/, + qr/"Query Text": "PREPARE get_class\(name\) AS SELECT \* FROM pg_class WHERE relname = \$1"/, "prepared query text logged, json mode"); like( diff --git a/src/backend/commands/prepare.c b/src/backend/commands/prepare.c index 34b6410d6a2..11b330ab73d 100644 --- a/src/backend/commands/prepare.c +++ b/src/backend/commands/prepare.c @@ -27,6 +27,7 @@ #include "commands/prepare.h" #include "funcapi.h" #include "nodes/nodeFuncs.h" +#include "nodes/queryjumble.h" #include "parser/parse_coerce.h" #include "parser/parse_collate.h" #include "parser/parse_expr.h" @@ -64,6 +65,7 @@ PrepareQuery(ParseState *pstate, PrepareStmt *stmt, Oid *argtypes = NULL; int nargs; List *query_list; + const char *new_query; /* * Disallow empty-string statement name (conflicts with protocol-level @@ -80,14 +82,49 @@ PrepareQuery(ParseState *pstate, PrepareStmt *stmt, */ rawstmt = makeNode(RawStmt); rawstmt->stmt = stmt->query; - rawstmt->stmt_location = stmt_location; - rawstmt->stmt_len = stmt_len; + + /* + * Extract the query text if possible. + * + * If we have a statement location, we can extract the relevant part of the + * possibly multi-statement query string. If not just use what we were + * given. + */ + if (stmt_location < 0) + { + rawstmt->stmt_location = stmt_location; + rawstmt->stmt_len = stmt_len; + new_query = pstate->p_sourcetext; + } + else + { + const char *cleaned; + char *tmp; + + rawstmt->stmt_len = stmt_len; + cleaned = CleanQuerytext(pstate->p_sourcetext, &stmt_location, + &rawstmt->stmt_len); + + if (rawstmt->stmt_len == 0) + rawstmt->stmt_len = strlen(cleaned); + + /* + * CleanQuerytext() removes any leading whitespace and returns a + * pointer to the first actual character, so the cleaned query string + * is guaranteed to start at offset 0. + */ + rawstmt->stmt_location = 0; + tmp = palloc(rawstmt->stmt_len + 1); + strlcpy(tmp, cleaned, rawstmt->stmt_len + 1); + + new_query = tmp; + } /* * Create the CachedPlanSource before we do parse analysis, since it needs * to see the unmodified raw parse tree. */ - plansource = CreateCachedPlan(rawstmt, pstate->p_sourcetext, + plansource = CreateCachedPlan(rawstmt, new_query, CreateCommandTag(stmt->query)); /* Transform list of TypeNames to array of type OIDs */ diff --git a/src/test/regress/expected/prepare.out b/src/test/regress/expected/prepare.out index 5815e17b39c..c645a4e5d0e 100644 --- a/src/test/regress/expected/prepare.out +++ b/src/test/regress/expected/prepare.out @@ -6,7 +6,17 @@ SELECT name, statement, parameter_types, result_types FROM pg_prepared_statement ------+-----------+-----------------+-------------- (0 rows) -PREPARE q1 AS SELECT 1 AS a; +SELECT 'bingo'\; PREPARE q1 AS SELECT 1 AS a \; SELECT 42; + ?column? +---------- + bingo +(1 row) + + ?column? +---------- + 42 +(1 row) + EXECUTE q1; a --- @@ -14,9 +24,9 @@ EXECUTE q1; (1 row) SELECT name, statement, parameter_types, result_types FROM pg_prepared_statements; - name | statement | parameter_types | result_types -------+------------------------------+-----------------+-------------- - q1 | PREPARE q1 AS SELECT 1 AS a; | {} | {integer} + name | statement | parameter_types | result_types +------+-----------------------------+-----------------+-------------- + q1 | PREPARE q1 AS SELECT 1 AS a | {} | {integer} (1 row) -- should fail @@ -33,18 +43,18 @@ EXECUTE q1; PREPARE q2 AS SELECT 2 AS b; SELECT name, statement, parameter_types, result_types FROM pg_prepared_statements; - name | statement | parameter_types | result_types -------+------------------------------+-----------------+-------------- - q1 | PREPARE q1 AS SELECT 2; | {} | {integer} - q2 | PREPARE q2 AS SELECT 2 AS b; | {} | {integer} + name | statement | parameter_types | result_types +------+-----------------------------+-----------------+-------------- + q1 | PREPARE q1 AS SELECT 2 | {} | {integer} + q2 | PREPARE q2 AS SELECT 2 AS b | {} | {integer} (2 rows) -- sql92 syntax DEALLOCATE PREPARE q1; SELECT name, statement, parameter_types, result_types FROM pg_prepared_statements; - name | statement | parameter_types | result_types -------+------------------------------+-----------------+-------------- - q2 | PREPARE q2 AS SELECT 2 AS b; | {} | {integer} + name | statement | parameter_types | result_types +------+-----------------------------+-----------------+-------------- + q2 | PREPARE q2 AS SELECT 2 AS b | {} | {integer} (1 row) DEALLOCATE PREPARE q2; @@ -168,20 +178,20 @@ SELECT name, statement, parameter_types, result_types FROM pg_prepared_statement ------+------------------------------------------------------------------+----------------------------------------------------+-------------------------------------------------------------------------------------------------------------------------- q2 | PREPARE q2(text) AS +| {text} | {name,boolean,boolean} | SELECT datname, datistemplate, datallowconn +| | - | FROM pg_database WHERE datname = $1; | | + | FROM pg_database WHERE datname = $1 | | q3 | PREPARE q3(text, int, float, boolean, smallint) AS +| {text,integer,"double precision",boolean,smallint} | {integer,integer,integer,integer,integer,integer,integer,integer,integer,integer,integer,integer,integer,name,name,name} | SELECT * FROM tenk1 WHERE string4 = $1 AND (four = $2 OR+| | | ten = $3::bigint OR true = $4 OR odd = $5::int) +| | - | ORDER BY unique1; | | + | ORDER BY unique1 | | q5 | PREPARE q5(int, text) AS +| {integer,text} | {integer,integer,integer,integer,integer,integer,integer,integer,integer,integer,integer,integer,integer,name,name,name} | SELECT * FROM tenk1 WHERE unique1 = $1 OR stringu1 = $2 +| | - | ORDER BY unique1; | | + | ORDER BY unique1 | | q6 | PREPARE q6 AS +| {integer,name} | {integer,integer,integer,integer,integer,integer,integer,integer,integer,integer,integer,integer,integer,name,name,name} - | SELECT * FROM tenk1 WHERE unique1 = $1 AND stringu1 = $2; | | + | SELECT * FROM tenk1 WHERE unique1 = $1 AND stringu1 = $2 | | q7 | PREPARE q7(unknown) AS +| {path} | {text,path} - | SELECT * FROM road WHERE thepath = $1; | | + | SELECT * FROM road WHERE thepath = $1 | | q8 | PREPARE q8 AS +| {integer,name} | - | UPDATE tenk1 SET stringu1 = $2 WHERE unique1 = $1; | | + | UPDATE tenk1 SET stringu1 = $2 WHERE unique1 = $1 | | (6 rows) -- test DEALLOCATE ALL; diff --git a/src/test/regress/sql/prepare.sql b/src/test/regress/sql/prepare.sql index c6098dc95ce..0e7fe44725e 100644 --- a/src/test/regress/sql/prepare.sql +++ b/src/test/regress/sql/prepare.sql @@ -4,7 +4,7 @@ SELECT name, statement, parameter_types, result_types FROM pg_prepared_statements; -PREPARE q1 AS SELECT 1 AS a; +SELECT 'bingo'\; PREPARE q1 AS SELECT 1 AS a \; SELECT 42; EXECUTE q1; SELECT name, statement, parameter_types, result_types FROM pg_prepared_statements; -- 2.52.0