Skip to content

Commit

Permalink
Add result_types column to pg_prepared_statements view
Browse files Browse the repository at this point in the history
Containing the types of the columns returned by the prepared
statement.

Prompted by question from IRC user mlvzk.

Author: Dagfinn Ilmari Mannsåker <ilmari@ilmari.org>
Discussion: https://www.postgresql.org/message-id/flat/871qwpo7te.fsf@wibble.ilmari.org
  • Loading branch information
petere committed Jul 5, 2022
1 parent eb64cea commit 84ad713
Show file tree
Hide file tree
Showing 7 changed files with 74 additions and 52 deletions.
12 changes: 12 additions & 0 deletions doc/src/sgml/catalogs.sgml
Original file line number Diff line number Diff line change
Expand Up @@ -11502,6 +11502,18 @@ SELECT * FROM pg_locks pl LEFT JOIN pg_prepared_xacts ppx
</para></entry>
</row>

<row>
<entry role="catalog_table_entry"><para role="column_definition">
<structfield>result_types</structfield> <type>regtype[]</type>
</para>
<para>
The types of the columns returned by the prepared statement in the
form of an array of <type>regtype</type>. The OID corresponding
to an element of this array can be obtained by casting the
<type>regtype</type> value to <type>oid</type>.
</para></entry>
</row>

<row>
<entry role="catalog_table_entry"><para role="column_definition">
<structfield>from_sql</structfield> <type>bool</type>
Expand Down
19 changes: 14 additions & 5 deletions src/backend/commands/prepare.c
Original file line number Diff line number Diff line change
Expand Up @@ -683,8 +683,16 @@ pg_prepared_statement(PG_FUNCTION_ARGS)
hash_seq_init(&hash_seq, prepared_queries);
while ((prep_stmt = hash_seq_search(&hash_seq)) != NULL)
{
Datum values[7];
bool nulls[7];
TupleDesc result_desc;
Oid *result_types;
Datum values[8];
bool nulls[8];

result_desc = prep_stmt->plansource->resultDesc;
result_types = (Oid *) palloc(result_desc->natts * sizeof(Oid));

for (int i = 0; i < result_desc->natts; i++)
result_types[i] = result_desc->attrs[i].atttypid;

MemSet(nulls, 0, sizeof(nulls));

Expand All @@ -693,9 +701,10 @@ pg_prepared_statement(PG_FUNCTION_ARGS)
values[2] = TimestampTzGetDatum(prep_stmt->prepare_time);
values[3] = build_regtype_array(prep_stmt->plansource->param_types,
prep_stmt->plansource->num_params);
values[4] = BoolGetDatum(prep_stmt->from_sql);
values[5] = Int64GetDatumFast(prep_stmt->plansource->num_generic_plans);
values[6] = Int64GetDatumFast(prep_stmt->plansource->num_custom_plans);
values[4] = build_regtype_array(result_types, result_desc->natts);
values[5] = BoolGetDatum(prep_stmt->from_sql);
values[6] = Int64GetDatumFast(prep_stmt->plansource->num_generic_plans);
values[7] = Int64GetDatumFast(prep_stmt->plansource->num_custom_plans);

tuplestore_putvalues(rsinfo->setResult, rsinfo->setDesc,
values, nulls);
Expand Down
2 changes: 1 addition & 1 deletion src/include/catalog/catversion.h
Original file line number Diff line number Diff line change
Expand Up @@ -53,6 +53,6 @@
*/

/* yyyymmddN */
#define CATALOG_VERSION_NO 202205191
#define CATALOG_VERSION_NO 202207051

#endif
6 changes: 3 additions & 3 deletions src/include/catalog/pg_proc.dat
Original file line number Diff line number Diff line change
Expand Up @@ -8025,9 +8025,9 @@
proname => 'pg_prepared_statement', prorows => '1000', proretset => 't',
provolatile => 's', proparallel => 'r', prorettype => 'record',
proargtypes => '',
proallargtypes => '{text,text,timestamptz,_regtype,bool,int8,int8}',
proargmodes => '{o,o,o,o,o,o,o}',
proargnames => '{name,statement,prepare_time,parameter_types,from_sql,generic_plans,custom_plans}',
proallargtypes => '{text,text,timestamptz,_regtype,_regtype,bool,int8,int8}',
proargmodes => '{o,o,o,o,o,o,o,o}',
proargnames => '{name,statement,prepare_time,parameter_types,result_types,from_sql,generic_plans,custom_plans}',
prosrc => 'pg_prepared_statement' },
{ oid => '2511', descr => 'get the open cursors for this session',
proname => 'pg_cursor', prorows => '1000', proretset => 't',
Expand Down
72 changes: 36 additions & 36 deletions src/test/regress/expected/prepare.out
Original file line number Diff line number Diff line change
@@ -1,9 +1,9 @@
-- Regression tests for prepareable statements. We query the content
-- of the pg_prepared_statements view as prepared statements are
-- created and removed.
SELECT name, statement, parameter_types FROM pg_prepared_statements;
name | statement | parameter_types
------+-----------+-----------------
SELECT name, statement, parameter_types, result_types FROM pg_prepared_statements;
name | statement | parameter_types | result_types
------+-----------+-----------------+--------------
(0 rows)

PREPARE q1 AS SELECT 1 AS a;
Expand All @@ -13,10 +13,10 @@ EXECUTE q1;
1
(1 row)

SELECT name, statement, parameter_types FROM pg_prepared_statements;
name | statement | parameter_types
------+------------------------------+-----------------
q1 | PREPARE q1 AS SELECT 1 AS a; | {}
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}
(1 row)

-- should fail
Expand All @@ -32,26 +32,26 @@ EXECUTE q1;
(1 row)

PREPARE q2 AS SELECT 2 AS b;
SELECT name, statement, parameter_types FROM pg_prepared_statements;
name | statement | parameter_types
------+------------------------------+-----------------
q1 | PREPARE q1 AS SELECT 2; | {}
q2 | 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}
(2 rows)

-- sql92 syntax
DEALLOCATE PREPARE q1;
SELECT name, statement, parameter_types FROM pg_prepared_statements;
name | statement | parameter_types
------+------------------------------+-----------------
q2 | PREPARE q2 AS SELECT 2 AS b; | {}
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}
(1 row)

DEALLOCATE PREPARE q2;
-- the view should return the empty set again
SELECT name, statement, parameter_types FROM pg_prepared_statements;
name | statement | parameter_types
------+-----------+-----------------
SELECT name, statement, parameter_types, result_types FROM pg_prepared_statements;
name | statement | parameter_types | result_types
------+-----------+-----------------+--------------
(0 rows)

-- parameterized queries
Expand Down Expand Up @@ -159,24 +159,24 @@ PREPARE q6 AS
SELECT * FROM tenk1 WHERE unique1 = $1 AND stringu1 = $2;
PREPARE q7(unknown) AS
SELECT * FROM road WHERE thepath = $1;
SELECT name, statement, parameter_types FROM pg_prepared_statements
SELECT name, statement, parameter_types, result_types FROM pg_prepared_statements
ORDER BY name;
name | statement | parameter_types
------+------------------------------------------------------------------+----------------------------------------------------
q2 | PREPARE q2(text) AS +| {text}
| SELECT datname, datistemplate, datallowconn +|
| FROM pg_database WHERE datname = $1; |
q3 | PREPARE q3(text, int, float, boolean, smallint) AS +| {text,integer,"double precision",boolean,smallint}
| SELECT * FROM tenk1 WHERE string4 = $1 AND (four = $2 OR+|
| ten = $3::bigint OR true = $4 OR odd = $5::int) +|
| ORDER BY unique1; |
q5 | PREPARE q5(int, text) AS +| {integer,text}
| SELECT * FROM tenk1 WHERE unique1 = $1 OR stringu1 = $2 +|
| ORDER BY unique1; |
q6 | PREPARE q6 AS +| {integer,name}
| SELECT * FROM tenk1 WHERE unique1 = $1 AND stringu1 = $2; |
q7 | PREPARE q7(unknown) AS +| {path}
| SELECT * FROM road WHERE thepath = $1; |
name | statement | parameter_types | result_types
------+------------------------------------------------------------------+----------------------------------------------------+--------------------------------------------------------------------------------------------------------------------------
q2 | PREPARE q2(text) AS +| {text} | {name,boolean,boolean}
| SELECT datname, datistemplate, datallowconn +| |
| 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; | |
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; | |
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; | |
q7 | PREPARE q7(unknown) AS +| {path} | {text,path}
| SELECT * FROM road WHERE thepath = $1; | |
(5 rows)

-- test DEALLOCATE ALL;
Expand Down
3 changes: 2 additions & 1 deletion src/test/regress/expected/rules.out
Original file line number Diff line number Diff line change
Expand Up @@ -1423,10 +1423,11 @@ pg_prepared_statements| SELECT p.name,
p.statement,
p.prepare_time,
p.parameter_types,
p.result_types,
p.from_sql,
p.generic_plans,
p.custom_plans
FROM pg_prepared_statement() p(name, statement, prepare_time, parameter_types, from_sql, generic_plans, custom_plans);
FROM pg_prepared_statement() p(name, statement, prepare_time, parameter_types, result_types, from_sql, generic_plans, custom_plans);
pg_prepared_xacts| SELECT p.transaction,
p.gid,
p.prepared,
Expand Down
12 changes: 6 additions & 6 deletions src/test/regress/sql/prepare.sql
Original file line number Diff line number Diff line change
Expand Up @@ -2,12 +2,12 @@
-- of the pg_prepared_statements view as prepared statements are
-- created and removed.

SELECT name, statement, parameter_types FROM pg_prepared_statements;
SELECT name, statement, parameter_types, result_types FROM pg_prepared_statements;

PREPARE q1 AS SELECT 1 AS a;
EXECUTE q1;

SELECT name, statement, parameter_types FROM pg_prepared_statements;
SELECT name, statement, parameter_types, result_types FROM pg_prepared_statements;

-- should fail
PREPARE q1 AS SELECT 2;
Expand All @@ -18,16 +18,16 @@ PREPARE q1 AS SELECT 2;
EXECUTE q1;

PREPARE q2 AS SELECT 2 AS b;
SELECT name, statement, parameter_types FROM pg_prepared_statements;
SELECT name, statement, parameter_types, result_types FROM pg_prepared_statements;

-- sql92 syntax
DEALLOCATE PREPARE q1;

SELECT name, statement, parameter_types FROM pg_prepared_statements;
SELECT name, statement, parameter_types, result_types FROM pg_prepared_statements;

DEALLOCATE PREPARE q2;
-- the view should return the empty set again
SELECT name, statement, parameter_types FROM pg_prepared_statements;
SELECT name, statement, parameter_types, result_types FROM pg_prepared_statements;

-- parameterized queries
PREPARE q2(text) AS
Expand Down Expand Up @@ -71,7 +71,7 @@ PREPARE q6 AS
PREPARE q7(unknown) AS
SELECT * FROM road WHERE thepath = $1;

SELECT name, statement, parameter_types FROM pg_prepared_statements
SELECT name, statement, parameter_types, result_types FROM pg_prepared_statements
ORDER BY name;

-- test DEALLOCATE ALL;
Expand Down

0 comments on commit 84ad713

Please sign in to comment.