*** a/doc/src/sgml/plpgsql.sgml
--- b/doc/src/sgml/plpgsql.sgml
***************
*** 1077,1082 **** END;
--- 1077,1106 ----
+ If print_strict_params> is enabled for the function,
+ you will get information about the parameters passed to the
+ query in the DETAIL> part of the error message produced
+ when the requirements of STRICT are not met. You can change this
+ setting on a system-wide basis by setting
+ plpgsql.print_strict_params>, though only subsequent
+ function compilations will be affected. You can also enable it
+ on a per-function basis by using a compiler option:
+
+ CREATE FUNCTION get_userid(username text) RETURNS int
+ AS $$
+ #print_strict_params on
+ DECLARE
+ userid int;
+ BEGIN
+ SELECT users.userid INTO STRICT userid
+ FROM users WHERE users.username = get_userid.username;
+ RETURN userid;
+ END
+ $$ LANGUAGE plpgsql;
+
+
+
+
For INSERT>/UPDATE>/DELETE> with
RETURNING>, PL/pgSQL reports
an error for more than one returned row, even when
*** a/src/pl/plpgsql/src/pl_comp.c
--- b/src/pl/plpgsql/src/pl_comp.c
***************
*** 351,356 **** do_compile(FunctionCallInfo fcinfo,
--- 351,357 ----
function->fn_cxt = func_cxt;
function->out_param_varno = -1; /* set up for no OUT param */
function->resolve_option = plpgsql_variable_conflict;
+ function->print_strict_params = plpgsql_print_strict_params;
if (is_dml_trigger)
function->fn_is_trigger = PLPGSQL_DML_TRIGGER;
***************
*** 847,852 **** plpgsql_compile_inline(char *proc_source)
--- 848,854 ----
function->fn_cxt = func_cxt;
function->out_param_varno = -1; /* set up for no OUT param */
function->resolve_option = plpgsql_variable_conflict;
+ function->print_strict_params = plpgsql_print_strict_params;
plpgsql_ns_init();
plpgsql_ns_push(func_name);
*** a/src/pl/plpgsql/src/pl_exec.c
--- b/src/pl/plpgsql/src/pl_exec.c
***************
*** 221,226 **** static Portal exec_dynquery_with_params(PLpgSQL_execstate *estate,
--- 221,231 ----
PLpgSQL_expr *dynquery, List *params,
const char *portalname, int cursorOptions);
+ static char *format_expr_params(PLpgSQL_execstate *estate,
+ const PLpgSQL_expr *expr);
+ static char *format_preparedparamsdata(PLpgSQL_execstate *estate,
+ const PreparedParamsData *ppd);
+
/* ----------
* plpgsql_exec_function Called by the call handler for
***************
*** 3391,3408 **** exec_stmt_execsql(PLpgSQL_execstate *estate,
if (n == 0)
{
if (stmt->strict)
ereport(ERROR,
(errcode(ERRCODE_NO_DATA_FOUND),
! errmsg("query returned no rows")));
/* set the target to NULL(s) */
exec_move_row(estate, rec, row, NULL, tuptab->tupdesc);
}
else
{
if (n > 1 && (stmt->strict || stmt->mod_stmt))
ereport(ERROR,
(errcode(ERRCODE_TOO_MANY_ROWS),
! errmsg("query returned more than one row")));
/* Put the first result row into the target */
exec_move_row(estate, rec, row, tuptab->vals[0], tuptab->tupdesc);
}
--- 3396,3435 ----
if (n == 0)
{
if (stmt->strict)
+ {
+ char *errdetail;
+
+ if (estate->func->print_strict_params)
+ errdetail = format_expr_params(estate, expr);
+ else
+ errdetail = NULL;
+
ereport(ERROR,
(errcode(ERRCODE_NO_DATA_FOUND),
! errmsg("query returned no rows"),
! errdetail ?
! errdetail_internal("parameters: %s", errdetail) : 0));
! }
/* set the target to NULL(s) */
exec_move_row(estate, rec, row, NULL, tuptab->tupdesc);
}
else
{
if (n > 1 && (stmt->strict || stmt->mod_stmt))
+ {
+ char *errdetail;
+
+ if (estate->func->print_strict_params)
+ errdetail = format_expr_params(estate, expr);
+ else
+ errdetail = NULL;
+
ereport(ERROR,
(errcode(ERRCODE_TOO_MANY_ROWS),
! errmsg("query returned more than one row"),
! errdetail ?
! errdetail_internal("parameters: %s", errdetail) : 0));
! }
/* Put the first result row into the target */
exec_move_row(estate, rec, row, tuptab->vals[0], tuptab->tupdesc);
}
***************
*** 3442,3447 **** exec_stmt_dynexecute(PLpgSQL_execstate *estate,
--- 3469,3475 ----
Oid restype;
char *querystr;
int exec_res;
+ PreparedParamsData *ppd = NULL;
/*
* First we evaluate the string expression after the EXECUTE keyword. Its
***************
*** 3466,3479 **** exec_stmt_dynexecute(PLpgSQL_execstate *estate,
*/
if (stmt->params)
{
- PreparedParamsData *ppd;
-
ppd = exec_eval_using_params(estate, stmt->params);
exec_res = SPI_execute_with_args(querystr,
ppd->nargs, ppd->types,
ppd->values, ppd->nulls,
estate->readonly_func, 0);
- free_params_data(ppd);
}
else
exec_res = SPI_execute(querystr, estate->readonly_func, 0);
--- 3494,3504 ----
***************
*** 3565,3582 **** exec_stmt_dynexecute(PLpgSQL_execstate *estate,
if (n == 0)
{
if (stmt->strict)
ereport(ERROR,
(errcode(ERRCODE_NO_DATA_FOUND),
! errmsg("query returned no rows")));
/* set the target to NULL(s) */
exec_move_row(estate, rec, row, NULL, tuptab->tupdesc);
}
else
{
if (n > 1 && stmt->strict)
ereport(ERROR,
(errcode(ERRCODE_TOO_MANY_ROWS),
! errmsg("query returned more than one row")));
/* Put the first result row into the target */
exec_move_row(estate, rec, row, tuptab->vals[0], tuptab->tupdesc);
}
--- 3590,3630 ----
if (n == 0)
{
if (stmt->strict)
+ {
+ char *errdetail;
+
+ if (estate->func->print_strict_params)
+ errdetail = format_preparedparamsdata(estate, ppd);
+ else
+ errdetail = NULL;
+
ereport(ERROR,
(errcode(ERRCODE_NO_DATA_FOUND),
! errmsg("query returned no rows"),
! errdetail ?
! errdetail_internal("parameters: %s", errdetail) : 0));
! }
/* set the target to NULL(s) */
exec_move_row(estate, rec, row, NULL, tuptab->tupdesc);
}
else
{
if (n > 1 && stmt->strict)
+ {
+ char *errdetail;
+
+ if (estate->func->print_strict_params)
+ errdetail = format_preparedparamsdata(estate, ppd);
+ else
+ errdetail = NULL;
+
ereport(ERROR,
(errcode(ERRCODE_TOO_MANY_ROWS),
! errmsg("query returned more than one row"),
! errdetail ?
! errdetail_internal("parameters: %s", errdetail) : 0));
! }
!
/* Put the first result row into the target */
exec_move_row(estate, rec, row, tuptab->vals[0], tuptab->tupdesc);
}
***************
*** 3592,3597 **** exec_stmt_dynexecute(PLpgSQL_execstate *estate,
--- 3640,3648 ----
*/
}
+ if (ppd)
+ free_params_data(ppd);
+
/* Release any result from SPI_execute, as well as the querystring */
SPI_freetuptable(SPI_tuptable);
pfree(querystr);
***************
*** 6456,6458 **** exec_dynquery_with_params(PLpgSQL_execstate *estate,
--- 6507,6609 ----
return portal;
}
+
+ /*
+ * Return a formatted string with information about an expression's parameters,
+ * or NULL if the expression does not take any parameters.
+ */
+ static char *
+ format_expr_params(PLpgSQL_execstate *estate,
+ const PLpgSQL_expr *expr)
+ {
+ int paramno;
+ int dno;
+ StringInfoData paramstr;
+ Bitmapset *tmpset;
+
+ if (!expr->paramnos)
+ return NULL;
+
+ initStringInfo(¶mstr);
+ tmpset = bms_copy(expr->paramnos);
+ paramno = 0;
+ while ((dno = bms_first_member(tmpset)) >= 0)
+ {
+ Datum paramdatum;
+ Oid paramtypeid;
+ bool paramisnull;
+ int32 paramtypmod;
+ PLpgSQL_var *curvar;
+
+ curvar = (PLpgSQL_var *) estate->datums[dno];
+
+ exec_eval_datum(estate, (PLpgSQL_datum *) curvar, ¶mtypeid,
+ ¶mtypmod, ¶mdatum, ¶misnull);
+
+ appendStringInfo(¶mstr, "%s%s = ",
+ paramno > 0 ? ", " : "",
+ curvar->refname);
+
+ if (paramisnull)
+ appendStringInfoString(¶mstr, "NULL");
+ else
+ {
+ char *value = convert_value_to_string(estate, paramdatum, paramtypeid);
+ char *p;
+ appendStringInfoCharMacro(¶mstr, '\'');
+ for (p = value; *p; p++)
+ {
+ if (*p == '\'') /* double single quotes */
+ appendStringInfoCharMacro(¶mstr, *p);
+ appendStringInfoCharMacro(¶mstr, *p);
+ }
+ appendStringInfoCharMacro(¶mstr, '\'');
+ }
+
+ paramno++;
+ }
+ bms_free(tmpset);
+
+ return paramstr.data;
+ }
+
+ /*
+ * Return a formatted string with information about PreparedParamsData, or NULL
+ * if the there are no parameters.
+ */
+ static char *
+ format_preparedparamsdata(PLpgSQL_execstate *estate,
+ const PreparedParamsData *ppd)
+ {
+ int paramno;
+ StringInfoData paramstr;
+
+ if (!ppd)
+ return NULL;
+
+ initStringInfo(¶mstr);
+ for (paramno = 0; paramno < ppd->nargs; paramno++)
+ {
+ appendStringInfo(¶mstr, "%s$%d = ",
+ paramno > 0 ? ", " : "",
+ paramno + 1);
+
+ if (ppd->nulls[paramno] == 'n')
+ appendStringInfoString(¶mstr, "NULL");
+ else
+ {
+ char *value = convert_value_to_string(estate, ppd->values[paramno], ppd->types[paramno]);
+ char *p;
+ appendStringInfoCharMacro(¶mstr, '\'');
+ for (p = value; *p; p++)
+ {
+ if (*p == '\'') /* double single quotes */
+ appendStringInfoCharMacro(¶mstr, *p);
+ appendStringInfoCharMacro(¶mstr, *p);
+ }
+ appendStringInfoCharMacro(¶mstr, '\'');
+ }
+ }
+
+ return paramstr.data;
+ }
*** a/src/pl/plpgsql/src/pl_gram.y
--- b/src/pl/plpgsql/src/pl_gram.y
***************
*** 185,191 **** static List *read_raise_options(void);
%type for_variable
%type for_control
! %type any_identifier opt_block_label opt_label
%type proc_sect proc_stmts stmt_elsifs stmt_else
%type loop_body
--- 185,191 ----
%type for_variable
%type for_control
! %type any_identifier opt_block_label opt_label option_value
%type proc_sect proc_stmts stmt_elsifs stmt_else
%type loop_body
***************
*** 308,313 **** static List *read_raise_options(void);
--- 308,314 ----
%token K_PG_EXCEPTION_CONTEXT
%token K_PG_EXCEPTION_DETAIL
%token K_PG_EXCEPTION_HINT
+ %token K_PRINT_STRICT_PARAMS
%token K_PRIOR
%token K_QUERY
%token K_RAISE
***************
*** 354,359 **** comp_option : '#' K_OPTION K_DUMP
--- 355,369 ----
{
plpgsql_DumpExecTree = true;
}
+ | '#' K_PRINT_STRICT_PARAMS option_value
+ {
+ if (strcmp($3, "on") == 0)
+ plpgsql_curr_compile->print_strict_params = true;
+ else if (strcmp($3, "off") == 0)
+ plpgsql_curr_compile->print_strict_params = false;
+ else
+ elog(ERROR, "unrecognized print_strict_params option %s", $3);
+ }
| '#' K_VARIABLE_CONFLICT K_ERROR
{
plpgsql_curr_compile->resolve_option = PLPGSQL_RESOLVE_ERROR;
***************
*** 368,373 **** comp_option : '#' K_OPTION K_DUMP
--- 378,392 ----
}
;
+ option_value : T_WORD
+ {
+ $$ = $1.ident;
+ }
+ | unreserved_keyword
+ {
+ $$ = pstrdup($1);
+ }
+
opt_semi :
| ';'
;
***************
*** 2300,2305 **** unreserved_keyword :
--- 2319,2325 ----
| K_PG_EXCEPTION_DETAIL
| K_PG_EXCEPTION_HINT
| K_PRIOR
+ | K_PRINT_STRICT_PARAMS
| K_QUERY
| K_RELATIVE
| K_RESULT_OID
*** a/src/pl/plpgsql/src/pl_handler.c
--- b/src/pl/plpgsql/src/pl_handler.c
***************
*** 37,42 **** static const struct config_enum_entry variable_conflict_options[] = {
--- 37,44 ----
int plpgsql_variable_conflict = PLPGSQL_RESOLVE_ERROR;
+ bool plpgsql_print_strict_params = false;
+
/* Hook for plugins */
PLpgSQL_plugin **plugin_ptr = NULL;
***************
*** 66,71 **** _PG_init(void)
--- 68,81 ----
PGC_SUSET, 0,
NULL, NULL, NULL);
+ DefineCustomBoolVariable("plpgsql.print_strict_params",
+ gettext_noop("Print information about parameters in the DETAIL part of the error messages generated on INTO .. STRICT failures."),
+ NULL,
+ &plpgsql_print_strict_params,
+ false,
+ PGC_USERSET, 0,
+ NULL, NULL, NULL);
+
EmitWarningsOnPlaceholders("plpgsql");
plpgsql_HashTableInit();
*** a/src/pl/plpgsql/src/pl_scanner.c
--- b/src/pl/plpgsql/src/pl_scanner.c
***************
*** 140,145 **** static const ScanKeyword unreserved_keywords[] = {
--- 140,146 ----
PG_KEYWORD("pg_exception_context", K_PG_EXCEPTION_CONTEXT, UNRESERVED_KEYWORD)
PG_KEYWORD("pg_exception_detail", K_PG_EXCEPTION_DETAIL, UNRESERVED_KEYWORD)
PG_KEYWORD("pg_exception_hint", K_PG_EXCEPTION_HINT, UNRESERVED_KEYWORD)
+ PG_KEYWORD("print_strict_params", K_PRINT_STRICT_PARAMS, UNRESERVED_KEYWORD)
PG_KEYWORD("prior", K_PRIOR, UNRESERVED_KEYWORD)
PG_KEYWORD("query", K_QUERY, UNRESERVED_KEYWORD)
PG_KEYWORD("relative", K_RELATIVE, UNRESERVED_KEYWORD)
*** a/src/pl/plpgsql/src/plpgsql.h
--- b/src/pl/plpgsql/src/plpgsql.h
***************
*** 737,742 **** typedef struct PLpgSQL_function
--- 737,744 ----
PLpgSQL_resolve_option resolve_option;
+ bool print_strict_params;
+
int ndatums;
PLpgSQL_datum **datums;
PLpgSQL_stmt_block *action;
***************
*** 873,878 **** extern IdentifierLookup plpgsql_IdentifierLookup;
--- 875,882 ----
extern int plpgsql_variable_conflict;
+ extern bool plpgsql_print_strict_params;
+
extern bool plpgsql_check_syntax;
extern bool plpgsql_DumpExecTree;
*** a/src/test/regress/expected/plpgsql.out
--- b/src/test/regress/expected/plpgsql.out
***************
*** 3104,3109 **** select footest();
--- 3104,3213 ----
ERROR: query returned more than one row
CONTEXT: PL/pgSQL function footest() line 5 at EXECUTE statement
drop function footest();
+ -- test printing parameters after failure due to STRICT
+ set plpgsql.print_strict_params to true;
+ create or replace function footest() returns void as $$
+ declare
+ x record;
+ p1 int := 2;
+ p3 text := 'foo';
+ begin
+ -- no rows
+ select * from foo where f1 = p1 and f1::text = p3 into strict x;
+ raise notice 'x.f1 = %, x.f2 = %', x.f1, x.f2;
+ end$$ language plpgsql;
+ select footest();
+ ERROR: query returned no rows
+ DETAIL: parameters: p1 = '2', p3 = 'foo'
+ CONTEXT: PL/pgSQL function footest() line 8 at SQL statement
+ create or replace function footest() returns void as $$
+ declare
+ x record;
+ p1 int := 2;
+ p3 text := 'foo';
+ begin
+ -- too many rows
+ select * from foo where f1 > p1 or f1::text = p3 into strict x;
+ raise notice 'x.f1 = %, x.f2 = %', x.f1, x.f2;
+ end$$ language plpgsql;
+ select footest();
+ ERROR: query returned more than one row
+ DETAIL: parameters: p1 = '2', p3 = 'foo'
+ CONTEXT: PL/pgSQL function footest() line 8 at SQL statement
+ create or replace function footest() returns void as $$
+ declare x record;
+ begin
+ -- too many rows, no params
+ select * from foo where f1 > 3 into strict x;
+ raise notice 'x.f1 = %, x.f2 = %', x.f1, x.f2;
+ end$$ language plpgsql;
+ select footest();
+ ERROR: query returned more than one row
+ CONTEXT: PL/pgSQL function footest() line 5 at SQL statement
+ create or replace function footest() returns void as $$
+ declare x record;
+ begin
+ -- no rows
+ execute 'select * from foo where f1 = $1 or f1::text = $2' using 0, 'foo' into strict x;
+ raise notice 'x.f1 = %, x.f2 = %', x.f1, x.f2;
+ end$$ language plpgsql;
+ select footest();
+ ERROR: query returned no rows
+ DETAIL: parameters: $1 = '0', $2 = 'foo'
+ CONTEXT: PL/pgSQL function footest() line 5 at EXECUTE statement
+ create or replace function footest() returns void as $$
+ declare x record;
+ begin
+ -- too many rows
+ execute 'select * from foo where f1 > $1' using 1 into strict x;
+ raise notice 'x.f1 = %, x.f2 = %', x.f1, x.f2;
+ end$$ language plpgsql;
+ select footest();
+ ERROR: query returned more than one row
+ DETAIL: parameters: $1 = '1'
+ CONTEXT: PL/pgSQL function footest() line 5 at EXECUTE statement
+ create or replace function footest() returns void as $$
+ declare x record;
+ begin
+ -- too many rows, no parameters
+ execute 'select * from foo where f1 > 3' into strict x;
+ raise notice 'x.f1 = %, x.f2 = %', x.f1, x.f2;
+ end$$ language plpgsql;
+ select footest();
+ ERROR: query returned more than one row
+ CONTEXT: PL/pgSQL function footest() line 5 at EXECUTE statement
+ create or replace function footest() returns void as $$
+ -- override the global
+ #print_strict_params off
+ declare
+ x record;
+ p1 int := 2;
+ p3 text := 'foo';
+ begin
+ -- too many rows
+ select * from foo where f1 > p1 or f1::text = p3 into strict x;
+ raise notice 'x.f1 = %, x.f2 = %', x.f1, x.f2;
+ end$$ language plpgsql;
+ select footest();
+ ERROR: query returned more than one row
+ CONTEXT: PL/pgSQL function footest() line 10 at SQL statement
+ reset plpgsql.print_strict_params;
+ create or replace function footest() returns void as $$
+ -- override the global
+ #print_strict_params on
+ declare
+ x record;
+ p1 int := 2;
+ p3 text := 'foo';
+ begin
+ -- too many rows
+ select * from foo where f1 > p1 or f1::text = p3 into strict x;
+ raise notice 'x.f1 = %, x.f2 = %', x.f1, x.f2;
+ end$$ language plpgsql;
+ select footest();
+ ERROR: query returned more than one row
+ DETAIL: parameters: p1 = '2', p3 = 'foo'
+ CONTEXT: PL/pgSQL function footest() line 10 at SQL statement
-- test scrollable cursor support
create function sc_test() returns setof integer as $$
declare
*** a/src/test/regress/sql/plpgsql.sql
--- b/src/test/regress/sql/plpgsql.sql
***************
*** 2587,2592 **** select footest();
--- 2587,2694 ----
drop function footest();
+ -- test printing parameters after failure due to STRICT
+
+ set plpgsql.print_strict_params to true;
+
+ create or replace function footest() returns void as $$
+ declare
+ x record;
+ p1 int := 2;
+ p3 text := 'foo';
+ begin
+ -- no rows
+ select * from foo where f1 = p1 and f1::text = p3 into strict x;
+ raise notice 'x.f1 = %, x.f2 = %', x.f1, x.f2;
+ end$$ language plpgsql;
+
+ select footest();
+
+ create or replace function footest() returns void as $$
+ declare
+ x record;
+ p1 int := 2;
+ p3 text := 'foo';
+ begin
+ -- too many rows
+ select * from foo where f1 > p1 or f1::text = p3 into strict x;
+ raise notice 'x.f1 = %, x.f2 = %', x.f1, x.f2;
+ end$$ language plpgsql;
+
+ select footest();
+
+ create or replace function footest() returns void as $$
+ declare x record;
+ begin
+ -- too many rows, no params
+ select * from foo where f1 > 3 into strict x;
+ raise notice 'x.f1 = %, x.f2 = %', x.f1, x.f2;
+ end$$ language plpgsql;
+
+ select footest();
+
+ create or replace function footest() returns void as $$
+ declare x record;
+ begin
+ -- no rows
+ execute 'select * from foo where f1 = $1 or f1::text = $2' using 0, 'foo' into strict x;
+ raise notice 'x.f1 = %, x.f2 = %', x.f1, x.f2;
+ end$$ language plpgsql;
+
+ select footest();
+
+ create or replace function footest() returns void as $$
+ declare x record;
+ begin
+ -- too many rows
+ execute 'select * from foo where f1 > $1' using 1 into strict x;
+ raise notice 'x.f1 = %, x.f2 = %', x.f1, x.f2;
+ end$$ language plpgsql;
+
+ select footest();
+
+ create or replace function footest() returns void as $$
+ declare x record;
+ begin
+ -- too many rows, no parameters
+ execute 'select * from foo where f1 > 3' into strict x;
+ raise notice 'x.f1 = %, x.f2 = %', x.f1, x.f2;
+ end$$ language plpgsql;
+
+ select footest();
+
+ create or replace function footest() returns void as $$
+ -- override the global
+ #print_strict_params off
+ declare
+ x record;
+ p1 int := 2;
+ p3 text := 'foo';
+ begin
+ -- too many rows
+ select * from foo where f1 > p1 or f1::text = p3 into strict x;
+ raise notice 'x.f1 = %, x.f2 = %', x.f1, x.f2;
+ end$$ language plpgsql;
+
+ select footest();
+
+ reset plpgsql.print_strict_params;
+
+ create or replace function footest() returns void as $$
+ -- override the global
+ #print_strict_params on
+ declare
+ x record;
+ p1 int := 2;
+ p3 text := 'foo';
+ begin
+ -- too many rows
+ select * from foo where f1 > p1 or f1::text = p3 into strict x;
+ raise notice 'x.f1 = %, x.f2 = %', x.f1, x.f2;
+ end$$ language plpgsql;
+
+ select footest();
+
-- test scrollable cursor support
create function sc_test() returns setof integer as $$