in plpgsql. Clean up a couple of corner cases in the MOVE/FETCH syntax.
Pavel Stehule
-<!-- $PostgreSQL: pgsql/doc/src/sgml/plpgsql.sgml,v 1.142 2009/06/18 10:22:08 petere Exp $ -->
+<!-- $PostgreSQL: pgsql/doc/src/sgml/plpgsql.sgml,v 1.143 2009/09/29 20:05:29 tgl Exp $ -->
<chapter id="plpgsql">
<title><application>PL/pgSQL</application> - <acronym>SQL</acronym> Procedural Language</title>
</para>
<para>
- The options for the <replaceable>direction</replaceable> clause are
- the same as for <command>FETCH</>, namely
+ The <replaceable>direction</replaceable> clause can be any of the
+ variants allowed in the SQL <xref linkend="sql-fetch"
+ endterm="sql-fetch-title"> command, namely
<literal>NEXT</>,
<literal>PRIOR</>,
<literal>FIRST</>,
<literal>LAST</>,
<literal>ABSOLUTE</> <replaceable>count</replaceable>,
<literal>RELATIVE</> <replaceable>count</replaceable>,
- <literal>FORWARD</>, or
- <literal>BACKWARD</>.
+ <literal>ALL</>,
+ <literal>FORWARD</> <optional> <replaceable>count</replaceable> | <literal>ALL</> </optional>, or
+ <literal>BACKWARD</> <optional> <replaceable>count</replaceable> | <literal>ALL</> </optional>.
Omitting <replaceable>direction</replaceable> is the same
as specifying <literal>NEXT</>.
<replaceable>direction</replaceable> values that require moving
MOVE curs1;
MOVE LAST FROM curs3;
MOVE RELATIVE -2 FROM curs4;
+MOVE FORWARD 2 FROM curs4;
</programlisting>
</para>
</sect3>
*
*
* IDENTIFICATION
- * $PostgreSQL: pgsql/src/pl/plpgsql/src/gram.y,v 1.127 2009/07/22 02:31:38 joe Exp $
+ * $PostgreSQL: pgsql/src/pl/plpgsql/src/gram.y,v 1.128 2009/09/29 20:05:29 tgl Exp $
*
*-------------------------------------------------------------------------
*/
static PLpgSQL_type *read_datatype(int tok);
static PLpgSQL_stmt *make_execsql_stmt(const char *sqlstart, int lineno);
static PLpgSQL_stmt_fetch *read_fetch_direction(void);
+static void complete_direction(PLpgSQL_stmt_fetch *fetch,
+ bool *check_FROM);
static PLpgSQL_stmt *make_return_stmt(int lineno);
static PLpgSQL_stmt *make_return_next_stmt(int lineno);
static PLpgSQL_stmt *make_return_query_stmt(int lineno);
* Keyword tokens
*/
%token K_ALIAS
+%token K_ALL
%token K_ASSIGN
%token K_BEGIN
%token K_BY
if (yylex() != ';')
yyerror("syntax error");
+ /*
+ * We don't allow multiple rows in PL/pgSQL's FETCH
+ * statement, only in MOVE.
+ */
+ if (fetch->returns_multiple_rows)
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("FETCH statement cannot return multiple rows")));
+
fetch->lineno = $2;
fetch->rec = rec;
fetch->row = row;
}
+/*
+ * Read FETCH or MOVE direction clause (everything through FROM/IN).
+ */
static PLpgSQL_stmt_fetch *
read_fetch_direction(void)
{
fetch->direction = FETCH_FORWARD;
fetch->how_many = 1;
fetch->expr = NULL;
+ fetch->returns_multiple_rows = false;
/*
* Most of the direction keywords are not plpgsql keywords, so we
NULL);
check_FROM = false;
}
+ else if (pg_strcasecmp(yytext, "all") == 0)
+ {
+ fetch->how_many = FETCH_ALL;
+ fetch->returns_multiple_rows = true;
+ }
else if (pg_strcasecmp(yytext, "forward") == 0)
{
- /* use defaults */
+ complete_direction(fetch, &check_FROM);
}
else if (pg_strcasecmp(yytext, "backward") == 0)
{
fetch->direction = FETCH_BACKWARD;
+ complete_direction(fetch, &check_FROM);
}
- else if (tok != T_SCALAR)
+ else if (tok == K_FROM || tok == K_IN)
{
+ /* empty direction */
+ check_FROM = false;
+ }
+ else if (tok == T_SCALAR)
+ {
+ /* Assume there's no direction clause and tok is a cursor name */
plpgsql_push_back_token(tok);
- fetch->expr = read_sql_expression2(K_FROM, K_IN,
- "FROM or IN",
- NULL);
check_FROM = false;
}
else
{
- /* Assume there's no direction clause */
+ /*
+ * Assume it's a count expression with no preceding keyword.
+ * Note: we allow this syntax because core SQL does, but we don't
+ * document it because of the ambiguity with the omitted-direction
+ * case. For instance, "MOVE n IN c" will fail if n is a scalar.
+ * Perhaps this can be improved someday, but it's hardly worth a
+ * lot of work.
+ */
plpgsql_push_back_token(tok);
+ fetch->expr = read_sql_expression2(K_FROM, K_IN,
+ "FROM or IN",
+ NULL);
+ fetch->returns_multiple_rows = true;
check_FROM = false;
}
return fetch;
}
+/*
+ * Process remainder of FETCH/MOVE direction after FORWARD or BACKWARD.
+ * Allows these cases:
+ * FORWARD expr, FORWARD ALL, FORWARD
+ * BACKWARD expr, BACKWARD ALL, BACKWARD
+ */
+static void
+complete_direction(PLpgSQL_stmt_fetch *fetch, bool *check_FROM)
+{
+ int tok;
+
+ tok = yylex();
+ if (tok == 0)
+ yyerror("unexpected end of function definition");
+
+ if (tok == K_FROM || tok == K_IN)
+ {
+ *check_FROM = false;
+ return;
+ }
+
+ if (tok == K_ALL)
+ {
+ fetch->how_many = FETCH_ALL;
+ fetch->returns_multiple_rows = true;
+ *check_FROM = true;
+ return;
+ }
+
+ plpgsql_push_back_token(tok);
+ fetch->expr = read_sql_expression2(K_FROM, K_IN,
+ "FROM or IN",
+ NULL);
+ fetch->returns_multiple_rows = true;
+ *check_FROM = false;
+}
+
static PLpgSQL_stmt *
make_return_stmt(int lineno)
/* copy expression query without SELECT keyword (expr->query + 7) */
Assert(strncmp(expr->query, "SELECT ", 7) == 0);
-
+
/* And do the string hacking */
initStringInfo(&ds);
- appendStringInfo(&ds, "SELECT $%d IN(%s)",
+ appendStringInfo(&ds, "SELECT $%d IN(%s)",
nparams + 1,
expr->query + 7);
*
*
* IDENTIFICATION
- * $PostgreSQL: pgsql/src/pl/plpgsql/src/pl_funcs.c,v 1.80 2009/07/22 02:31:38 joe Exp $
+ * $PostgreSQL: pgsql/src/pl/plpgsql/src/pl_funcs.c,v 1.81 2009/09/29 20:05:29 tgl Exp $
*
*-------------------------------------------------------------------------
*/
printf("\n");
}
else
- printf("%d\n", stmt->how_many);
+ printf("%ld\n", stmt->how_many);
dump_indent -= 2;
}
*
*
* IDENTIFICATION
- * $PostgreSQL: pgsql/src/pl/plpgsql/src/plpgsql.h,v 1.116 2009/09/22 23:43:42 tgl Exp $
+ * $PostgreSQL: pgsql/src/pl/plpgsql/src/plpgsql.h,v 1.117 2009/09/29 20:05:29 tgl Exp $
*
*-------------------------------------------------------------------------
*/
PLpgSQL_row *row;
int curvar; /* cursor variable to fetch from */
FetchDirection direction; /* fetch direction */
- int how_many; /* count, if constant (expr is NULL) */
+ long how_many; /* count, if constant (expr is NULL) */
PLpgSQL_expr *expr; /* count, if expression */
bool is_move; /* is this a fetch or move? */
+ bool returns_multiple_rows; /* can return more than one row? */
} PLpgSQL_stmt_fetch;
*
*
* IDENTIFICATION
- * $PostgreSQL: pgsql/src/pl/plpgsql/src/scan.l,v 1.71 2009/07/13 00:42:18 tgl Exp $
+ * $PostgreSQL: pgsql/src/pl/plpgsql/src/scan.l,v 1.72 2009/09/29 20:05:29 tgl Exp $
*
*-------------------------------------------------------------------------
*/
= { return K_ASSIGN; }
\.\. { return K_DOTDOT; }
alias { return K_ALIAS; }
+all { return K_ALL; }
begin { return K_BEGIN; }
by { return K_BY; }
case { return K_CASE; }
0
(3 rows)
+create or replace function sc_test() returns setof integer as $$
+declare
+ c refcursor;
+ x integer;
+begin
+ open c scroll for execute 'select f1 from int4_tbl';
+ fetch last from c into x;
+ while found loop
+ return next x;
+ move backward 2 from c;
+ fetch relative -1 from c into x;
+ end loop;
+ close c;
+end;
+$$ language plpgsql;
+select * from sc_test();
+ sc_test
+-------------
+ -2147483647
+ 123456
+(2 rows)
+
create or replace function sc_test() returns setof integer as $$
declare
c cursor for select * from generate_series(1, 10);
9
(3 rows)
+create or replace function sc_test() returns setof integer as $$
+declare
+ c cursor for select * from generate_series(1, 10);
+ x integer;
+begin
+ open c;
+ move forward all in c;
+ fetch backward from c into x;
+ if found then
+ return next x;
+ end if;
+ close c;
+end;
+$$ language plpgsql;
+select * from sc_test();
+ sc_test
+---------
+ 10
+(1 row)
+
drop function sc_test();
-- test qualified variable names
create function pl_qual_names (param1 int) returns void as $$
-- Test anonymous code blocks.
DO $$
DECLARE r record;
-BEGIN
+BEGIN
FOR r IN SELECT rtrim(roomno) AS roomno, comment FROM Room ORDER BY roomno
LOOP
RAISE NOTICE '%, %', r.roomno, r.comment;
^
DO LANGUAGE plpgsql $$
DECLARE r record;
-BEGIN
+BEGIN
FOR r IN SELECT rtrim(roomno) AS roomno, foo FROM Room ORDER BY roomno
LOOP
RAISE NOTICE '%, %', r.roomno, r.comment;
select * from sc_test();
+create or replace function sc_test() returns setof integer as $$
+declare
+ c refcursor;
+ x integer;
+begin
+ open c scroll for execute 'select f1 from int4_tbl';
+ fetch last from c into x;
+ while found loop
+ return next x;
+ move backward 2 from c;
+ fetch relative -1 from c into x;
+ end loop;
+ close c;
+end;
+$$ language plpgsql;
+
+select * from sc_test();
+
create or replace function sc_test() returns setof integer as $$
declare
c cursor for select * from generate_series(1, 10);
select * from sc_test();
+create or replace function sc_test() returns setof integer as $$
+declare
+ c cursor for select * from generate_series(1, 10);
+ x integer;
+begin
+ open c;
+ move forward all in c;
+ fetch backward from c into x;
+ if found then
+ return next x;
+ end if;
+ close c;
+end;
+$$ language plpgsql;
+
+select * from sc_test();
+
drop function sc_test();
-- test qualified variable names
DO $$
DECLARE r record;
-BEGIN
+BEGIN
FOR r IN SELECT rtrim(roomno) AS roomno, comment FROM Room ORDER BY roomno
LOOP
RAISE NOTICE '%, %', r.roomno, r.comment;
DO LANGUAGE plpgsql $$
DECLARE r record;
-BEGIN
+BEGIN
FOR r IN SELECT rtrim(roomno) AS roomno, foo FROM Room ORDER BY roomno
LOOP
RAISE NOTICE '%, %', r.roomno, r.comment;