From 960d7ff02266b3e11684470d140ed26957aece5f Mon Sep 17 00:00:00 2001 From: Tom Lane Date: Tue, 29 Sep 2009 20:05:29 +0000 Subject: [PATCH] Allow MOVE FORWARD n, MOVE BACKWARD n, MOVE FORWARD ALL, MOVE BACKWARD ALL in plpgsql. Clean up a couple of corner cases in the MOVE/FETCH syntax. Pavel Stehule --- doc/src/sgml/plpgsql.sgml | 13 ++-- src/pl/plpgsql/src/gram.y | 91 ++++++++++++++++++++++++--- src/pl/plpgsql/src/pl_funcs.c | 4 +- src/pl/plpgsql/src/plpgsql.h | 5 +- src/pl/plpgsql/src/scan.l | 3 +- src/test/regress/expected/plpgsql.out | 46 +++++++++++++- src/test/regress/sql/plpgsql.sql | 39 +++++++++++- 7 files changed, 178 insertions(+), 23 deletions(-) diff --git a/doc/src/sgml/plpgsql.sgml b/doc/src/sgml/plpgsql.sgml index f430bcfad0..65d508c37e 100644 --- a/doc/src/sgml/plpgsql.sgml +++ b/doc/src/sgml/plpgsql.sgml @@ -1,4 +1,4 @@ - + <application>PL/pgSQL</application> - <acronym>SQL</acronym> Procedural Language @@ -2655,16 +2655,18 @@ MOVE direction { FROM | IN } < - The options for the direction clause are - the same as for FETCH, namely + The direction clause can be any of the + variants allowed in the SQL command, namely NEXT, PRIOR, FIRST, LAST, ABSOLUTE count, RELATIVE count, - FORWARD, or - BACKWARD. + ALL, + FORWARD count | ALL , or + BACKWARD count | ALL . Omitting direction is the same as specifying NEXT. direction values that require moving @@ -2678,6 +2680,7 @@ MOVE direction { FROM | IN } < MOVE curs1; MOVE LAST FROM curs3; MOVE RELATIVE -2 FROM curs4; +MOVE FORWARD 2 FROM curs4; diff --git a/src/pl/plpgsql/src/gram.y b/src/pl/plpgsql/src/gram.y index cb9dcbc5a5..c876b875e6 100644 --- a/src/pl/plpgsql/src/gram.y +++ b/src/pl/plpgsql/src/gram.y @@ -9,7 +9,7 @@ * * * 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 $ * *------------------------------------------------------------------------- */ @@ -48,6 +48,8 @@ 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); 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); @@ -178,6 +180,7 @@ static List *read_raise_options(void); * Keyword tokens */ %token K_ALIAS +%token K_ALL %token K_ASSIGN %token K_BEGIN %token K_BY @@ -1622,6 +1625,15 @@ stmt_fetch : K_FETCH lno opt_fetch_direction cursor_variable K_INTO 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; @@ -2252,6 +2264,9 @@ make_execsql_stmt(const char *sqlstart, int lineno) } +/* + * Read FETCH or MOVE direction clause (everything through FROM/IN). + */ static PLpgSQL_stmt_fetch * read_fetch_direction(void) { @@ -2269,6 +2284,7 @@ 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 @@ -2311,26 +2327,46 @@ read_fetch_direction(void) 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; } @@ -2345,6 +2381,43 @@ read_fetch_direction(void) 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) @@ -3043,11 +3116,11 @@ make_case(int lineno, PLpgSQL_expr *t_expr, /* 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); diff --git a/src/pl/plpgsql/src/pl_funcs.c b/src/pl/plpgsql/src/pl_funcs.c index cb2cb963ed..d814e8f4f3 100644 --- a/src/pl/plpgsql/src/pl_funcs.c +++ b/src/pl/plpgsql/src/pl_funcs.c @@ -8,7 +8,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 $ * *------------------------------------------------------------------------- */ @@ -854,7 +854,7 @@ dump_cursor_direction(PLpgSQL_stmt_fetch *stmt) printf("\n"); } else - printf("%d\n", stmt->how_many); + printf("%ld\n", stmt->how_many); dump_indent -= 2; } diff --git a/src/pl/plpgsql/src/plpgsql.h b/src/pl/plpgsql/src/plpgsql.h index fb627e7a89..55ddf54ab2 100644 --- a/src/pl/plpgsql/src/plpgsql.h +++ b/src/pl/plpgsql/src/plpgsql.h @@ -8,7 +8,7 @@ * * * 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 $ * *------------------------------------------------------------------------- */ @@ -517,9 +517,10 @@ typedef struct 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; diff --git a/src/pl/plpgsql/src/scan.l b/src/pl/plpgsql/src/scan.l index 2449779120..b309d81187 100644 --- a/src/pl/plpgsql/src/scan.l +++ b/src/pl/plpgsql/src/scan.l @@ -9,7 +9,7 @@ * * * 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 $ * *------------------------------------------------------------------------- */ @@ -147,6 +147,7 @@ param \${digit}+ = { 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; } diff --git a/src/test/regress/expected/plpgsql.out b/src/test/regress/expected/plpgsql.out index ca4c9dc233..a362fb5370 100644 --- a/src/test/regress/expected/plpgsql.out +++ b/src/test/regress/expected/plpgsql.out @@ -3025,6 +3025,28 @@ select * from sc_test(); 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); @@ -3052,6 +3074,26 @@ select * from sc_test(); 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 $$ @@ -3864,7 +3906,7 @@ drop function strtest(); -- 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; @@ -3887,7 +3929,7 @@ LINE 1: DO LANGUAGE plpgsql $$begin return 1; end$$; ^ 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; diff --git a/src/test/regress/sql/plpgsql.sql b/src/test/regress/sql/plpgsql.sql index 96f89144b7..80de8eb72f 100644 --- a/src/test/regress/sql/plpgsql.sql +++ b/src/test/regress/sql/plpgsql.sql @@ -2511,6 +2511,24 @@ $$ language plpgsql; 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); @@ -2533,6 +2551,23 @@ $$ 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); + 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 @@ -3084,7 +3119,7 @@ drop function strtest(); 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; @@ -3096,7 +3131,7 @@ DO LANGUAGE plpgsql $$begin return 1; end$$; 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;