Pavel Stehule, with some improvements by myself.
-<!-- $PostgreSQL: pgsql/doc/src/sgml/plpgsql.sgml,v 1.125 2008/03/28 00:21:55 tgl Exp $ -->
+<!-- $PostgreSQL: pgsql/doc/src/sgml/plpgsql.sgml,v 1.126 2008/04/01 03:51:09 tgl Exp $ -->
<chapter id="plpgsql">
<title><application>PL/pgSQL</application> - <acronym>SQL</acronym> Procedural Language</title>
<command>EXECUTE</command> statement is provided:
<synopsis>
-EXECUTE <replaceable class="command">command-string</replaceable> <optional> INTO <optional>STRICT</optional> <replaceable>target</replaceable> </optional>;
+EXECUTE <replaceable class="command">command-string</replaceable> <optional> INTO <optional>STRICT</optional> <replaceable>target</replaceable> </optional> <optional> USING <replaceable>expression</replaceable> <optional>, ...</optional> </optional>;
</synopsis>
where <replaceable>command-string</replaceable> is an expression
yielding a string (of type <type>text</type>) containing the
- command to be executed and <replaceable>target</replaceable> is a
- record variable, row variable, or a comma-separated list of
- simple variables and record/row fields.
+ command to be executed. The optional <replaceable>target</replaceable>
+ is a record variable, a row variable, or a comma-separated list of
+ simple variables and record/row fields, into which the results of
+ the command will be stored. The optional <literal>USING</> expressions
+ supply values to be inserted into the command.
</para>
<para>
No substitution of <application>PL/pgSQL</> variables is done on the
computed command string. Any required variable values must be inserted
- in the command string as it is constructed.
+ in the command string as it is constructed; or you can use parameters
+ as described below.
</para>
<para>
If the <literal>STRICT</> option is given, an error is reported
unless the query produces exactly one row.
</para>
+
+ <para>
+ The command string can use parameter values, which are referenced
+ in the command as <literal>$1</>, <literal>$2</>, etc.
+ These symbols refer to values supplied in the <literal>USING</>
+ clause. This method is often preferable to inserting data values
+ into the command string as text: it avoids run-time overhead of
+ converting the values to text and back, and it is much less prone
+ to SQL-injection attacks since there is no need for quoting or escaping.
+ An example is:
+<programlisting>
+EXECUTE 'SELECT count(*) FROM mytable WHERE inserted_by = $1 AND inserted <= $2'
+ INTO c
+ USING checked_user, checked_date;
+</programlisting>
+
+ Note that parameter symbols can only be used for data values
+ — if you want to use dynamically determined table or column
+ names, you must insert them into the command string textually.
+ For example, if the preceding query needed to be done against a
+ dynamically selected table, you could do this:
+<programlisting>
+EXECUTE 'SELECT count(*) FROM '
+ || tabname::regclass
+ || ' WHERE inserted_by = $1 AND inserted <= $2'
+ INTO c
+ USING checked_user, checked_date;
+</programlisting>
+ </para>
+
+ <para>
+ An <command>EXECUTE</> with a simple constant command string and some
+ <literal>USING</> parameters, as in the first example above, is
+ functionally equivalent to just writing the command directly in
+ <application>PL/pgSQL</application> and allowing replacement of
+ <application>PL/pgSQL</application> variables to happen automatically.
+ The important difference is that <command>EXECUTE</> will re-plan
+ the command on each execution, generating a plan that is specific
+ to the current parameter values; whereas
+ <application>PL/pgSQL</application> normally creates a generic plan
+ and caches it for re-use. In situations where the best plan depends
+ strongly on the parameter values, <command>EXECUTE</> can be
+ significantly faster; while when the plan is not sensitive to parameter
+ values, re-planning will be a waste.
+ </para>
<para>
<command>SELECT INTO</command> is not currently supported within
rows:
<synopsis>
<optional> <<<replaceable>label</replaceable>>> </optional>
-FOR <replaceable>target</replaceable> IN EXECUTE <replaceable>text_expression</replaceable> LOOP
+FOR <replaceable>target</replaceable> IN EXECUTE <replaceable>text_expression</replaceable> <optional> USING <replaceable>expression</replaceable> <optional>, ...</optional> </optional> LOOP
<replaceable>statements</replaceable>
END LOOP <optional> <replaceable>label</replaceable> </optional>;
</synopsis>
on each entry to the <literal>FOR</> loop. This allows the programmer to
choose the speed of a preplanned query or the flexibility of a dynamic
query, just as with a plain <command>EXECUTE</command> statement.
+ As with <command>EXECUTE</command>, parameter values can be inserted
+ into the dynamic command via <literal>USING</>.
</para>
</sect2>
*
*
* IDENTIFICATION
- * $PostgreSQL: pgsql/src/pl/plpgsql/src/gram.y,v 1.108 2008/01/01 19:46:00 momjian Exp $
+ * $PostgreSQL: pgsql/src/pl/plpgsql/src/gram.y,v 1.109 2008/04/01 03:51:09 tgl Exp $
*
*-------------------------------------------------------------------------
*/
static PLpgSQL_expr *read_sql_construct(int until,
int until2,
+ int until3,
const char *expected,
const char *sqlstart,
bool isexpression,
bool valid_sql,
int *endtoken);
+static PLpgSQL_expr *read_sql_expression2(int until, int until2,
+ const char *expected,
+ int *endtoken);
static PLpgSQL_expr *read_sql_stmt(const char *sqlstart);
static PLpgSQL_type *read_datatype(int tok);
static PLpgSQL_stmt *make_execsql_stmt(const char *sqlstart, int lineno);
%token K_THEN
%token K_TO
%token K_TYPE
+%token K_USING
%token K_WARNING
%token K_WHEN
%token K_WHILE
{
PLpgSQL_stmt_dynfors *new;
PLpgSQL_expr *expr;
+ int term;
- expr = plpgsql_read_expression(K_LOOP, "LOOP");
+ expr = read_sql_expression2(K_LOOP, K_USING,
+ "LOOP or USING",
+ &term);
new = palloc0(sizeof(PLpgSQL_stmt_dynfors));
new->cmd_type = PLPGSQL_STMT_DYNFORS;
}
new->query = expr;
+ if (term == K_USING)
+ {
+ do
+ {
+ expr = read_sql_expression2(',', K_LOOP,
+ ", or LOOP",
+ &term);
+ new->params = lappend(new->params, expr);
+ } while (term == ',');
+ }
+
$$ = (PLpgSQL_stmt *) new;
}
else
*/
expr1 = read_sql_construct(K_DOTDOT,
K_LOOP,
+ 0,
"LOOP",
"SELECT ",
true,
check_sql_expr(expr1->query);
/* Read and check the second one */
- expr2 = read_sql_construct(K_LOOP,
- K_BY,
- "LOOP",
- "SELECT ",
- true,
- true,
- &tok);
+ expr2 = read_sql_expression2(K_LOOP, K_BY,
+ "LOOP",
+ &tok);
/* Get the BY clause if any */
if (tok == K_BY)
- expr_by = plpgsql_read_expression(K_LOOP, "LOOP");
+ expr_by = plpgsql_read_expression(K_LOOP,
+ "LOOP");
else
expr_by = NULL;
if (tok == ',')
{
- PLpgSQL_expr *expr;
- int term;
-
- for (;;)
+ do
{
- expr = read_sql_construct(',', ';', ", or ;",
- "SELECT ",
- true, true, &term);
+ PLpgSQL_expr *expr;
+
+ expr = read_sql_expression2(',', ';',
+ ", or ;",
+ &tok);
new->params = lappend(new->params, expr);
- if (term == ';')
- break;
- }
+ } while (tok == ',');
}
$$ = (PLpgSQL_stmt *)new;
PLpgSQL_expr *expr;
int endtoken;
- expr = read_sql_construct(K_INTO, ';', "INTO|;",
+ expr = read_sql_construct(K_INTO, K_USING, ';',
+ "INTO or USING or ;",
"SELECT ",
true, true, &endtoken);
new->strict = false;
new->rec = NULL;
new->row = NULL;
+ new->params = NIL;
/* If we found "INTO", collect the argument */
if (endtoken == K_INTO)
{
new->into = true;
read_into_target(&new->rec, &new->row, &new->strict);
- if (yylex() != ';')
+ endtoken = yylex();
+ if (endtoken != ';' && endtoken != K_USING)
yyerror("syntax error");
}
+ /* If we found "USING", collect the argument(s) */
+ if (endtoken == K_USING)
+ {
+ do
+ {
+ expr = read_sql_expression2(',', ';',
+ ", or ;",
+ &endtoken);
+ new->params = lappend(new->params, expr);
+ } while (endtoken == ',');
+ }
+
$$ = (PLpgSQL_stmt *)new;
}
;
$$ = (PLpgSQL_stmt *)fetch;
}
;
-
+
stmt_move : K_MOVE lno opt_fetch_direction cursor_variable ';'
{
PLpgSQL_stmt_fetch *fetch = $3;
}
+/* Convenience routine to read an expression with one possible terminator */
PLpgSQL_expr *
plpgsql_read_expression(int until, const char *expected)
{
- return read_sql_construct(until, 0, expected, "SELECT ", true, true, NULL);
+ return read_sql_construct(until, 0, 0, expected,
+ "SELECT ", true, true, NULL);
}
+/* Convenience routine to read an expression with two possible terminators */
+static PLpgSQL_expr *
+read_sql_expression2(int until, int until2, const char *expected,
+ int *endtoken)
+{
+ return read_sql_construct(until, until2, 0, expected,
+ "SELECT ", true, true, endtoken);
+}
+
+/* Convenience routine to read a SQL statement that must end with ';' */
static PLpgSQL_expr *
read_sql_stmt(const char *sqlstart)
{
- return read_sql_construct(';', 0, ";", sqlstart, false, true, NULL);
+ return read_sql_construct(';', 0, 0, ";",
+ sqlstart, false, true, NULL);
}
/*
*
* until: token code for expected terminator
* until2: token code for alternate terminator (pass 0 if none)
+ * until3: token code for another alternate terminator (pass 0 if none)
* expected: text to use in complaining that terminator was not found
* sqlstart: text to prefix to the accumulated SQL text
* isexpression: whether to say we're reading an "expression" or a "statement"
* valid_sql: whether to check the syntax of the expr (prefixed with sqlstart)
* endtoken: if not NULL, ending token is stored at *endtoken
- * (this is only interesting if until2 isn't zero)
+ * (this is only interesting if until2 or until3 isn't zero)
*/
static PLpgSQL_expr *
read_sql_construct(int until,
int until2,
+ int until3,
const char *expected,
const char *sqlstart,
bool isexpression,
break;
if (tok == until2 && parenlevel == 0)
break;
+ if (tok == until3 && parenlevel == 0)
+ break;
if (tok == '(' || tok == '[')
parenlevel++;
else if (tok == ')' || tok == ']')
else if (pg_strcasecmp(yytext, "absolute") == 0)
{
fetch->direction = FETCH_ABSOLUTE;
- fetch->expr = read_sql_construct(K_FROM, K_IN, "FROM or IN",
- "SELECT ", true, true, NULL);
+ fetch->expr = read_sql_expression2(K_FROM, K_IN,
+ "FROM or IN",
+ NULL);
check_FROM = false;
}
else if (pg_strcasecmp(yytext, "relative") == 0)
{
fetch->direction = FETCH_RELATIVE;
- fetch->expr = read_sql_construct(K_FROM, K_IN, "FROM or IN",
- "SELECT ", true, true, NULL);
+ fetch->expr = read_sql_expression2(K_FROM, K_IN,
+ "FROM or IN",
+ NULL);
check_FROM = false;
}
else if (pg_strcasecmp(yytext, "forward") == 0)
else if (tok != T_SCALAR)
{
plpgsql_push_back_token(tok);
- fetch->expr = read_sql_construct(K_FROM, K_IN, "FROM or IN",
- "SELECT ", true, true, NULL);
+ fetch->expr = read_sql_expression2(K_FROM, K_IN,
+ "FROM or IN",
+ NULL);
check_FROM = false;
}
else
new = palloc0(sizeof(PLpgSQL_stmt_return_query));
new->cmd_type = PLPGSQL_STMT_RETURN_QUERY;
new->lineno = lineno;
- new->query = read_sql_construct(';', 0, ")", "", false, true, NULL);
+ new->query = read_sql_stmt("");
return (PLpgSQL_stmt *) new;
}
*
*
* IDENTIFICATION
- * $PostgreSQL: pgsql/src/pl/plpgsql/src/pl_exec.c,v 1.207 2008/03/28 00:21:56 tgl Exp $
+ * $PostgreSQL: pgsql/src/pl/plpgsql/src/pl_exec.c,v 1.208 2008/04/01 03:51:09 tgl Exp $
*
*-------------------------------------------------------------------------
*/
static const char *const raise_skip_msg = "RAISE";
+typedef struct
+{
+ int nargs; /* number of arguments */
+ Oid *types; /* types of arguments */
+ Datum *values; /* evaluated argument values */
+ char *nulls; /* null markers (' '/'n' style) */
+ bool *freevals; /* which arguments are pfree-able */
+} PreparedParamsData;
+
/*
* All plpgsql function executions within a single transaction share the same
* executor EState for evaluating "simple" expressions. Each function call
static void exec_set_found(PLpgSQL_execstate *estate, bool state);
static void plpgsql_create_econtext(PLpgSQL_execstate *estate);
static void free_var(PLpgSQL_var *var);
+static PreparedParamsData *exec_eval_using_params(PLpgSQL_execstate *estate,
+ List *params);
+static void free_params_data(PreparedParamsData *ppd);
/* ----------
exec_eval_cleanup(estate);
/*
- * Call SPI_execute() without preparing a saved plan.
+ * Execute the query without preparing a saved plan.
*/
- exec_res = SPI_execute(querystr, estate->readonly_func, 0);
+ 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);
switch (exec_res)
{
PLpgSQL_row *row = NULL;
SPITupleTable *tuptab;
int n;
- SPIPlanPtr plan;
Portal portal;
bool found = false;
exec_eval_cleanup(estate);
/*
- * Prepare a plan and open an implicit cursor for the query
+ * Open an implicit cursor for the query. We use SPI_cursor_open_with_args
+ * even when there are no params, because this avoids making and freeing
+ * one copy of the plan.
*/
- plan = SPI_prepare(querystr, 0, NULL);
- if (plan == NULL)
- elog(ERROR, "SPI_prepare failed for \"%s\": %s",
- querystr, SPI_result_code_string(SPI_result));
- portal = SPI_cursor_open(NULL, plan, NULL, NULL,
- estate->readonly_func);
+ if (stmt->params)
+ {
+ PreparedParamsData *ppd;
+
+ ppd = exec_eval_using_params(estate, stmt->params);
+ portal = SPI_cursor_open_with_args(NULL,
+ querystr,
+ ppd->nargs, ppd->types,
+ ppd->values, ppd->nulls,
+ estate->readonly_func, 0);
+ free_params_data(ppd);
+ }
+ else
+ {
+ portal = SPI_cursor_open_with_args(NULL,
+ querystr,
+ 0, NULL,
+ NULL, NULL,
+ estate->readonly_func, 0);
+ }
+
if (portal == NULL)
elog(ERROR, "could not open implicit cursor for query \"%s\": %s",
querystr, SPI_result_code_string(SPI_result));
pfree(querystr);
- SPI_freeplan(plan);
/*
* Fetch the initial 10 tuples
var->freeval = false;
}
}
+
+/*
+ * exec_eval_using_params --- evaluate params of USING clause
+ */
+static PreparedParamsData *
+exec_eval_using_params(PLpgSQL_execstate *estate, List *params)
+{
+ PreparedParamsData *ppd;
+ int nargs;
+ int i;
+ ListCell *lc;
+
+ ppd = (PreparedParamsData *) palloc(sizeof(PreparedParamsData));
+ nargs = list_length(params);
+
+ ppd->nargs = nargs;
+ ppd->types = (Oid *) palloc(nargs * sizeof(Oid));
+ ppd->values = (Datum *) palloc(nargs * sizeof(Datum));
+ ppd->nulls = (char *) palloc(nargs * sizeof(char));
+ ppd->freevals = (bool *) palloc(nargs * sizeof(bool));
+
+ i = 0;
+ foreach(lc, params)
+ {
+ PLpgSQL_expr *param = (PLpgSQL_expr *) lfirst(lc);
+ bool isnull;
+
+ ppd->values[i] = exec_eval_expr(estate, param,
+ &isnull,
+ &ppd->types[i]);
+ ppd->nulls[i] = isnull ? 'n' : ' ';
+ ppd->freevals[i] = false;
+
+ /* pass-by-ref non null values must be copied into plpgsql context */
+ if (!isnull)
+ {
+ int16 typLen;
+ bool typByVal;
+
+ get_typlenbyval(ppd->types[i], &typLen, &typByVal);
+ if (!typByVal)
+ {
+ ppd->values[i] = datumCopy(ppd->values[i], typByVal, typLen);
+ ppd->freevals[i] = true;
+ }
+ }
+
+ exec_eval_cleanup(estate);
+
+ i++;
+ }
+
+ return ppd;
+}
+
+/*
+ * free_params_data --- pfree all pass-by-reference values used in USING clause
+ */
+static void
+free_params_data(PreparedParamsData *ppd)
+{
+ int i;
+
+ for (i = 0; i < ppd->nargs; i++)
+ {
+ if (ppd->freevals[i])
+ pfree(DatumGetPointer(ppd->values[i]));
+ }
+
+ pfree(ppd->types);
+ pfree(ppd->values);
+ pfree(ppd->nulls);
+ pfree(ppd->freevals);
+
+ pfree(ppd);
+}
*
*
* IDENTIFICATION
- * $PostgreSQL: pgsql/src/pl/plpgsql/src/pl_funcs.c,v 1.67 2008/01/01 19:46:00 momjian Exp $
+ * $PostgreSQL: pgsql/src/pl/plpgsql/src/pl_funcs.c,v 1.68 2008/04/01 03:51:09 tgl Exp $
*
*-------------------------------------------------------------------------
*/
stmt->strict ? " STRICT" : "",
stmt->row->rowno, stmt->row->refname);
}
+ if (stmt->params != NIL)
+ {
+ ListCell *lc;
+ int i;
+
+ dump_ind();
+ printf(" USING\n");
+ dump_indent += 2;
+ i = 1;
+ foreach(lc, stmt->params)
+ {
+ dump_ind();
+ printf(" parameter %d: ", i++);
+ dump_expr((PLpgSQL_expr *) lfirst(lc));
+ printf("\n");
+ }
+ dump_indent -= 2;
+ }
dump_indent -= 2;
}
dump_dynfors(PLpgSQL_stmt_dynfors *stmt)
{
dump_ind();
- printf("FORS %s EXECUTE ", (stmt->rec != NULL) ? stmt->rec->refname : stmt->row->refname);
+ printf("FORS %s EXECUTE ",
+ (stmt->rec != NULL) ? stmt->rec->refname : stmt->row->refname);
dump_expr(stmt->query);
printf("\n");
+ if (stmt->params != NIL)
+ {
+ ListCell *lc;
+ int i;
+ dump_indent += 2;
+ dump_ind();
+ printf(" USING\n");
+ dump_indent += 2;
+ i = 1;
+ foreach(lc, stmt->params)
+ {
+ dump_ind();
+ printf(" parameter $%d: ", i++);
+ dump_expr((PLpgSQL_expr *) lfirst(lc));
+ printf("\n");
+ }
+ dump_indent -= 4;
+ }
dump_stmts(stmt->body);
-
dump_ind();
printf(" ENDFORS\n");
}
*
*
* IDENTIFICATION
- * $PostgreSQL: pgsql/src/pl/plpgsql/src/plpgsql.h,v 1.95 2008/01/01 19:46:00 momjian Exp $
+ * $PostgreSQL: pgsql/src/pl/plpgsql/src/plpgsql.h,v 1.96 2008/04/01 03:51:09 tgl Exp $
*
*-------------------------------------------------------------------------
*/
PLpgSQL_row *row;
PLpgSQL_expr *query;
List *body; /* List of statements */
+ List *params; /* USING expressions */
} PLpgSQL_stmt_dynfors;
bool strict; /* INTO STRICT flag */
PLpgSQL_rec *rec; /* INTO target, if record */
PLpgSQL_row *row; /* INTO target, if row */
+ List *params; /* USING expressions */
} PLpgSQL_stmt_dynexecute;
*
*
* IDENTIFICATION
- * $PostgreSQL: pgsql/src/pl/plpgsql/src/scan.l,v 1.60 2008/01/01 19:46:00 momjian Exp $
+ * $PostgreSQL: pgsql/src/pl/plpgsql/src/scan.l,v 1.61 2008/04/01 03:51:09 tgl Exp $
*
*-------------------------------------------------------------------------
*/
then { return K_THEN; }
to { return K_TO; }
type { return K_TYPE; }
+using { return K_USING; }
warning { return K_WARNING; }
when { return K_WHEN; }
while { return K_WHILE; }
}
<IN_DOLLARQUOTE>{dolqinside} { }
<IN_DOLLARQUOTE>. { /* needed for $ inside the quoted text */ }
-<IN_DOLLARQUOTE><<EOF>> {
+<IN_DOLLARQUOTE><<EOF>> {
plpgsql_error_lineno = start_lineno;
ereport(ERROR,
(errcode(ERRCODE_DATATYPE_MISMATCH),
* scenarios there's no need to get the decoded value.)
*
* Note: we expect the literal to be the most recently lexed token. This
- * would not work well if we supported multiple-token pushback or if
+ * would not work well if we supported multiple-token pushback or if
* plpgsql_yylex() wanted to read ahead beyond a T_STRING token.
*/
char *
c9f0f895fb98ab9159f51fd0297e236d | 8 | t
(9 rows)
+-- test EXECUTE USING
+create function exc_using(int, text) returns int as $$
+declare i int;
+begin
+ for i in execute 'select * from generate_series(1,$1)' using $1+1 loop
+ raise notice '%', i;
+ end loop;
+ execute 'select $2 + $2*3 + length($1)' into i using $2,$1;
+ return i;
+end
+$$ language plpgsql;
+select exc_using(5, 'foobar');
+NOTICE: 1
+NOTICE: 2
+NOTICE: 3
+NOTICE: 4
+NOTICE: 5
+NOTICE: 6
+ exc_using
+-----------
+ 26
+(1 row)
+
end;
$$ language plpgsql;
-select * from ret_query2(8);
\ No newline at end of file
+select * from ret_query2(8);
+
+-- test EXECUTE USING
+create function exc_using(int, text) returns int as $$
+declare i int;
+begin
+ for i in execute 'select * from generate_series(1,$1)' using $1+1 loop
+ raise notice '%', i;
+ end loop;
+ execute 'select $2 + $2*3 + length($1)' into i using $2,$1;
+ return i;
+end
+$$ language plpgsql;
+
+select exc_using(5, 'foobar');