Commit 347dd6a1 authored by Tom Lane's avatar Tom Lane

Make plpgsql support FOR over a query specified by a cursor declaration,

for improved compatibility with Oracle.

Pavel Stehule, with some fixes by me.
parent 26043592
This diff is collapsed.
......@@ -9,7 +9,7 @@
*
*
* IDENTIFICATION
* $PostgreSQL: pgsql/src/pl/plpgsql/src/gram.y,v 1.109 2008/04/01 03:51:09 tgl Exp $
* $PostgreSQL: pgsql/src/pl/plpgsql/src/gram.y,v 1.110 2008/04/06 23:43:29 tgl Exp $
*
*-------------------------------------------------------------------------
*/
......@@ -50,6 +50,8 @@ static void plpgsql_sql_error_callback(void *arg);
static char *check_label(const char *yytxt);
static void check_labels(const char *start_label,
const char *end_label);
static PLpgSQL_expr *read_cursor_args(PLpgSQL_var *cursor,
int until, const char *expected);
%}
......@@ -861,21 +863,15 @@ stmt_for : opt_block_label K_FOR for_control loop_body
new->body = $4.stmts;
$$ = (PLpgSQL_stmt *) new;
}
else if ($3->cmd_type == PLPGSQL_STMT_FORS)
{
PLpgSQL_stmt_fors *new;
new = (PLpgSQL_stmt_fors *) $3;
new->label = $1;
new->body = $4.stmts;
$$ = (PLpgSQL_stmt *) new;
}
else
{
PLpgSQL_stmt_dynfors *new;
PLpgSQL_stmt_forq *new;
Assert($3->cmd_type == PLPGSQL_STMT_DYNFORS);
new = (PLpgSQL_stmt_dynfors *) $3;
Assert($3->cmd_type == PLPGSQL_STMT_FORS ||
$3->cmd_type == PLPGSQL_STMT_FORC ||
$3->cmd_type == PLPGSQL_STMT_DYNFORS);
/* forq is the common supertype of all three */
new = (PLpgSQL_stmt_forq *) $3;
new->label = $1;
new->body = $4.stmts;
$$ = (PLpgSQL_stmt *) new;
......@@ -892,9 +888,9 @@ for_control :
{
int tok = yylex();
/* Simple case: EXECUTE is a dynamic FOR loop */
if (tok == K_EXECUTE)
{
/* EXECUTE means it's a dynamic FOR loop */
PLpgSQL_stmt_dynfors *new;
PLpgSQL_expr *expr;
int term;
......@@ -942,6 +938,47 @@ for_control :
$$ = (PLpgSQL_stmt *) new;
}
else if (tok == T_SCALAR &&
yylval.scalar->dtype == PLPGSQL_DTYPE_VAR &&
((PLpgSQL_var *) yylval.scalar)->datatype->typoid == REFCURSOROID)
{
/* It's FOR var IN cursor */
PLpgSQL_stmt_forc *new;
PLpgSQL_var *cursor = (PLpgSQL_var *) yylval.scalar;
char *varname;
new = (PLpgSQL_stmt_forc *) palloc0(sizeof(PLpgSQL_stmt_forc));
new->cmd_type = PLPGSQL_STMT_FORC;
new->lineno = $1;
new->curvar = cursor->varno;
/* Should have had a single variable name */
plpgsql_error_lineno = $2.lineno;
if ($2.scalar && $2.row)
ereport(ERROR,
(errcode(ERRCODE_SYNTAX_ERROR),
errmsg("cursor FOR loop must have just one target variable")));
/* create loop's private RECORD variable */
plpgsql_convert_ident($2.name, &varname, 1);
new->rec = plpgsql_build_record(varname,
$2.lineno,
true);
/* can't use an unbound cursor this way */
if (cursor->cursor_explicit_expr == NULL)
ereport(ERROR,
(errcode(ERRCODE_SYNTAX_ERROR),
errmsg("cursor FOR loop must use a bound cursor variable")));
/* collect cursor's parameters if any */
new->argquery = read_cursor_args(cursor,
K_LOOP,
"LOOP");
$$ = (PLpgSQL_stmt *) new;
}
else
{
PLpgSQL_expr *expr1;
......@@ -1412,81 +1449,8 @@ stmt_open : K_OPEN lno cursor_variable
}
else
{
if ($3->cursor_explicit_argrow >= 0)
{
char *cp;
tok = yylex();
if (tok != '(')
{
plpgsql_error_lineno = plpgsql_scanner_lineno();
ereport(ERROR,
(errcode(ERRCODE_SYNTAX_ERROR),
errmsg("cursor \"%s\" has arguments",
$3->refname)));
}
/*
* Push back the '(', else read_sql_stmt
* will complain about unbalanced parens.
*/
plpgsql_push_back_token(tok);
new->argquery = read_sql_stmt("SELECT ");
/*
* Now remove the leading and trailing parens,
* because we want "select 1, 2", not
* "select (1, 2)".
*/
cp = new->argquery->query;
if (strncmp(cp, "SELECT", 6) != 0)
{
plpgsql_error_lineno = plpgsql_scanner_lineno();
/* internal error */
elog(ERROR, "expected \"SELECT (\", got \"%s\"",
new->argquery->query);
}
cp += 6;
while (*cp == ' ') /* could be more than 1 space here */
cp++;
if (*cp != '(')
{
plpgsql_error_lineno = plpgsql_scanner_lineno();
/* internal error */
elog(ERROR, "expected \"SELECT (\", got \"%s\"",
new->argquery->query);
}
*cp = ' ';
cp += strlen(cp) - 1;
if (*cp != ')')
yyerror("expected \")\"");
*cp = '\0';
}
else
{
tok = yylex();
if (tok == '(')
{
plpgsql_error_lineno = plpgsql_scanner_lineno();
ereport(ERROR,
(errcode(ERRCODE_SYNTAX_ERROR),
errmsg("cursor \"%s\" has no arguments",
$3->refname)));
}
if (tok != ';')
{
plpgsql_error_lineno = plpgsql_scanner_lineno();
ereport(ERROR,
(errcode(ERRCODE_SYNTAX_ERROR),
errmsg("syntax error at \"%s\"",
yytext)));
}
}
/* predefined cursor query, so read args */
new->argquery = read_cursor_args($3, ';', ";");
}
$$ = (PLpgSQL_stmt *)new;
......@@ -2578,6 +2542,97 @@ check_labels(const char *start_label, const char *end_label)
}
}
/*
* Read the arguments (if any) for a cursor, followed by the until token
*
* If cursor has no args, just swallow the until token and return NULL.
* If it does have args, we expect to see "( expr [, expr ...] )" followed
* by the until token. Consume all that and return a SELECT query that
* evaluates the expression(s) (without the outer parens).
*/
static PLpgSQL_expr *
read_cursor_args(PLpgSQL_var *cursor, int until, const char *expected)
{
PLpgSQL_expr *expr;
int tok;
char *cp;
tok = yylex();
if (cursor->cursor_explicit_argrow < 0)
{
/* No arguments expected */
if (tok == '(')
{
plpgsql_error_lineno = plpgsql_scanner_lineno();
ereport(ERROR,
(errcode(ERRCODE_SYNTAX_ERROR),
errmsg("cursor \"%s\" has no arguments",
cursor->refname)));
}
if (tok != until)
{
plpgsql_error_lineno = plpgsql_scanner_lineno();
ereport(ERROR,
(errcode(ERRCODE_SYNTAX_ERROR),
errmsg("syntax error at \"%s\"",
yytext)));
}
return NULL;
}
/* Else better provide arguments */
if (tok != '(')
{
plpgsql_error_lineno = plpgsql_scanner_lineno();
ereport(ERROR,
(errcode(ERRCODE_SYNTAX_ERROR),
errmsg("cursor \"%s\" has arguments",
cursor->refname)));
}
/*
* Push back the '(', else plpgsql_read_expression
* will complain about unbalanced parens.
*/
plpgsql_push_back_token(tok);
expr = plpgsql_read_expression(until, expected);
/*
* Now remove the leading and trailing parens,
* because we want "SELECT 1, 2", not "SELECT (1, 2)".
*/
cp = expr->query;
if (strncmp(cp, "SELECT", 6) != 0)
{
plpgsql_error_lineno = plpgsql_scanner_lineno();
/* internal error */
elog(ERROR, "expected \"SELECT (\", got \"%s\"", expr->query);
}
cp += 6;
while (*cp == ' ') /* could be more than 1 space here */
cp++;
if (*cp != '(')
{
plpgsql_error_lineno = plpgsql_scanner_lineno();
/* internal error */
elog(ERROR, "expected \"SELECT (\", got \"%s\"", expr->query);
}
*cp = ' ';
cp += strlen(cp) - 1;
if (*cp != ')')
yyerror("expected \")\"");
*cp = '\0';
return expr;
}
/* Needed to avoid conflict between different prefix settings: */
#undef yylex
......
......@@ -8,7 +8,7 @@
*
*
* IDENTIFICATION
* $PostgreSQL: pgsql/src/pl/plpgsql/src/pl_comp.c,v 1.123 2008/03/27 03:57:34 tgl Exp $
* $PostgreSQL: pgsql/src/pl/plpgsql/src/pl_comp.c,v 1.124 2008/04/06 23:43:29 tgl Exp $
*
*-------------------------------------------------------------------------
*/
......@@ -575,25 +575,11 @@ do_compile(FunctionCallInfo fcinfo,
errhint("You probably want to use TG_NARGS and TG_ARGV instead.")));
/* Add the record for referencing NEW */
rec = palloc0(sizeof(PLpgSQL_rec));
rec->dtype = PLPGSQL_DTYPE_REC;
rec->refname = pstrdup("new");
rec->tup = NULL;
rec->tupdesc = NULL;
rec->freetup = false;
plpgsql_adddatum((PLpgSQL_datum *) rec);
plpgsql_ns_additem(PLPGSQL_NSTYPE_REC, rec->recno, rec->refname);
rec = plpgsql_build_record("new", 0, true);
function->new_varno = rec->recno;
/* Add the record for referencing OLD */
rec = palloc0(sizeof(PLpgSQL_rec));
rec->dtype = PLPGSQL_DTYPE_REC;
rec->refname = pstrdup("old");
rec->tup = NULL;
rec->tupdesc = NULL;
rec->freetup = false;
plpgsql_adddatum((PLpgSQL_datum *) rec);
plpgsql_ns_additem(PLPGSQL_NSTYPE_REC, rec->recno, rec->refname);
rec = plpgsql_build_record("old", 0, true);
function->old_varno = rec->recno;
/* Add the variable tg_name */
......@@ -1481,21 +1467,10 @@ plpgsql_build_variable(const char *refname, int lineno, PLpgSQL_type *dtype,
}
case PLPGSQL_TTYPE_REC:
{
/*
* "record" type -- build a variable-contents record variable
*/
/* "record" type -- build a record variable */
PLpgSQL_rec *rec;
rec = palloc0(sizeof(PLpgSQL_rec));
rec->dtype = PLPGSQL_DTYPE_REC;
rec->refname = pstrdup(refname);
rec->lineno = lineno;
plpgsql_adddatum((PLpgSQL_datum *) rec);
if (add2namespace)
plpgsql_ns_additem(PLPGSQL_NSTYPE_REC,
rec->recno,
refname);
rec = plpgsql_build_record(refname, lineno, add2namespace);
result = (PLpgSQL_variable *) rec;
break;
}
......@@ -1515,6 +1490,28 @@ plpgsql_build_variable(const char *refname, int lineno, PLpgSQL_type *dtype,
return result;
}
/*
* Build empty named record variable, and optionally add it to namespace
*/
PLpgSQL_rec *
plpgsql_build_record(const char *refname, int lineno, bool add2namespace)
{
PLpgSQL_rec *rec;
rec = palloc0(sizeof(PLpgSQL_rec));
rec->dtype = PLPGSQL_DTYPE_REC;
rec->refname = pstrdup(refname);
rec->lineno = lineno;
rec->tup = NULL;
rec->tupdesc = NULL;
rec->freetup = false;
plpgsql_adddatum((PLpgSQL_datum *) rec);
if (add2namespace)
plpgsql_ns_additem(PLPGSQL_NSTYPE_REC, rec->recno, rec->refname);
return rec;
}
/*
* Build a row-variable data structure given the pg_class OID.
*/
......
This diff is collapsed.
......@@ -8,7 +8,7 @@
*
*
* IDENTIFICATION
* $PostgreSQL: pgsql/src/pl/plpgsql/src/pl_funcs.c,v 1.68 2008/04/01 03:51:09 tgl Exp $
* $PostgreSQL: pgsql/src/pl/plpgsql/src/pl_funcs.c,v 1.69 2008/04/06 23:43:29 tgl Exp $
*
*-------------------------------------------------------------------------
*/
......@@ -482,6 +482,8 @@ plpgsql_stmt_typename(PLpgSQL_stmt *stmt)
return _("FOR with integer loop variable");
case PLPGSQL_STMT_FORS:
return _("FOR over SELECT rows");
case PLPGSQL_STMT_FORC:
return _("FOR over cursor");
case PLPGSQL_STMT_EXIT:
return "EXIT";
case PLPGSQL_STMT_RETURN:
......@@ -528,6 +530,7 @@ static void dump_loop(PLpgSQL_stmt_loop *stmt);
static void dump_while(PLpgSQL_stmt_while *stmt);
static void dump_fori(PLpgSQL_stmt_fori *stmt);
static void dump_fors(PLpgSQL_stmt_fors *stmt);
static void dump_forc(PLpgSQL_stmt_forc *stmt);
static void dump_exit(PLpgSQL_stmt_exit *stmt);
static void dump_return(PLpgSQL_stmt_return *stmt);
static void dump_return_next(PLpgSQL_stmt_return_next *stmt);
......@@ -581,6 +584,9 @@ dump_stmt(PLpgSQL_stmt *stmt)
case PLPGSQL_STMT_FORS:
dump_fors((PLpgSQL_stmt_fors *) stmt);
break;
case PLPGSQL_STMT_FORC:
dump_forc((PLpgSQL_stmt_forc *) stmt);
break;
case PLPGSQL_STMT_EXIT:
dump_exit((PLpgSQL_stmt_exit *) stmt);
break;
......@@ -775,6 +781,29 @@ dump_fors(PLpgSQL_stmt_fors *stmt)
printf(" ENDFORS\n");
}
static void
dump_forc(PLpgSQL_stmt_forc *stmt)
{
dump_ind();
printf("FORC %s ", stmt->rec->refname);
printf("curvar=%d\n", stmt->curvar);
dump_indent += 2;
if (stmt->argquery != NULL)
{
dump_ind();
printf(" arguments = ");
dump_expr(stmt->argquery);
printf("\n");
}
dump_indent -= 2;
dump_stmts(stmt->body);
dump_ind();
printf(" ENDFORC\n");
}
static void
dump_open(PLpgSQL_stmt_open *stmt)
{
......
......@@ -8,7 +8,7 @@
*
*
* IDENTIFICATION
* $PostgreSQL: pgsql/src/pl/plpgsql/src/plpgsql.h,v 1.96 2008/04/01 03:51:09 tgl Exp $
* $PostgreSQL: pgsql/src/pl/plpgsql/src/plpgsql.h,v 1.97 2008/04/06 23:43:29 tgl Exp $
*
*-------------------------------------------------------------------------
*/
......@@ -80,6 +80,7 @@ enum
PLPGSQL_STMT_WHILE,
PLPGSQL_STMT_FORI,
PLPGSQL_STMT_FORS,
PLPGSQL_STMT_FORC,
PLPGSQL_STMT_EXIT,
PLPGSQL_STMT_RETURN,
PLPGSQL_STMT_RETURN_NEXT,
......@@ -409,6 +410,21 @@ typedef struct
} PLpgSQL_stmt_fori;
/*
* PLpgSQL_stmt_forq represents a FOR statement running over a SQL query.
* It is the common supertype of PLpgSQL_stmt_fors, PLpgSQL_stmt_forc
* and PLpgSQL_dynfors.
*/
typedef struct
{
int cmd_type;
int lineno;
char *label;
PLpgSQL_rec *rec;
PLpgSQL_row *row;
List *body; /* List of statements */
} PLpgSQL_stmt_forq;
typedef struct
{ /* FOR statement running over SELECT */
int cmd_type;
......@@ -416,10 +432,23 @@ typedef struct
char *label;
PLpgSQL_rec *rec;
PLpgSQL_row *row;
PLpgSQL_expr *query;
List *body; /* List of statements */
/* end of fields that must match PLpgSQL_stmt_forq */
PLpgSQL_expr *query;
} PLpgSQL_stmt_fors;
typedef struct
{ /* FOR statement running over cursor */
int cmd_type;
int lineno;
char *label;
PLpgSQL_rec *rec;
PLpgSQL_row *row;
List *body; /* List of statements */
/* end of fields that must match PLpgSQL_stmt_forq */
int curvar;
PLpgSQL_expr *argquery; /* cursor arguments if any */
} PLpgSQL_stmt_forc;
typedef struct
{ /* FOR statement running over EXECUTE */
......@@ -428,8 +457,9 @@ typedef struct
char *label;
PLpgSQL_rec *rec;
PLpgSQL_row *row;
PLpgSQL_expr *query;
List *body; /* List of statements */
/* end of fields that must match PLpgSQL_stmt_forq */
PLpgSQL_expr *query;
List *params; /* USING expressions */
} PLpgSQL_stmt_dynfors;
......@@ -738,6 +768,8 @@ extern PLpgSQL_type *plpgsql_build_datatype(Oid typeOid, int32 typmod);
extern PLpgSQL_variable *plpgsql_build_variable(const char *refname, int lineno,
PLpgSQL_type *dtype,
bool add2namespace);
extern PLpgSQL_rec *plpgsql_build_record(const char *refname, int lineno,
bool add2namespace);
extern PLpgSQL_condition *plpgsql_parse_err_condition(char *condname);
extern void plpgsql_adddatum(PLpgSQL_datum *new);
extern int plpgsql_add_initdatums(int **varnos);
......
......@@ -3151,3 +3151,119 @@ NOTICE: 6
26
(1 row)
-- test FOR-over-cursor
create or replace function forc01() returns void as $$
declare
c cursor(r1 integer, r2 integer)
for select * from generate_series(r1,r2) i;
c2 cursor
for select * from generate_series(41,43) i;
begin
for r in c(5,7) loop
raise notice '% from %', r.i, c;
end loop;
-- again, to test if cursor was closed properly
for r in c(9,10) loop
raise notice '% from %', r.i, c;
end loop;
-- and test a parameterless cursor
for r in c2 loop
raise notice '% from %', r.i, c2;
end loop;
-- and try it with a hand-assigned name
raise notice 'after loop, c2 = %', c2;
c2 := 'special_name';
for r in c2 loop
raise notice '% from %', r.i, c2;
end loop;
raise notice 'after loop, c2 = %', c2;
-- and try it with a generated name
-- (which we can't show in the output because it's variable)
c2 := null;
for r in c2 loop
raise notice '%', r.i;
end loop;
raise notice 'after loop, c2 = %', c2;
return;
end;
$$ language plpgsql;
select forc01();
NOTICE: 5 from c
NOTICE: 6 from c
NOTICE: 7 from c
NOTICE: 9 from c
NOTICE: 10 from c
NOTICE: 41 from c2
NOTICE: 42 from c2
NOTICE: 43 from c2
NOTICE: after loop, c2 = c2
NOTICE: 41 from special_name
NOTICE: 42 from special_name
NOTICE: 43 from special_name
NOTICE: after loop, c2 = special_name
NOTICE: 41
NOTICE: 42
NOTICE: 43
NOTICE: after loop, c2 = <NULL>
forc01
--------
(1 row)
-- try updating the cursor's current row
create temp table forc_test as
select n as i, n as j from generate_series(1,10) n;
create or replace function forc01() returns void as $$
declare
c cursor for select * from forc_test;
begin
for r in c loop
raise notice '%, %', r.i, r.j;
update forc_test set i = i * 100, j = r.j * 2 where current of c;
end loop;
end;
$$ language plpgsql;
select forc01();
NOTICE: 1, 1
NOTICE: 2, 2
NOTICE: 3, 3
NOTICE: 4, 4
NOTICE: 5, 5
NOTICE: 6, 6
NOTICE: 7, 7
NOTICE: 8, 8
NOTICE: 9, 9
NOTICE: 10, 10
forc01
--------
(1 row)
select * from forc_test;
i | j
------+----
100 | 2
200 | 4
300 | 6
400 | 8
500 | 10
600 | 12
700 | 14
800 | 16
900 | 18
1000 | 20
(10 rows)
drop function forc01();
-- fail because cursor has no query bound to it
create or replace function forc_bad() returns void as $$
declare
c refcursor;
begin
for r in c loop
raise notice '%', r.i;
end loop;
end;
$$ language plpgsql;
ERROR: cursor FOR loop must use a bound cursor variable
CONTEXT: compile of PL/pgSQL function "forc_bad" near line 4
......@@ -2595,3 +2595,77 @@ end
$$ language plpgsql;
select exc_using(5, 'foobar');
-- test FOR-over-cursor
create or replace function forc01() returns void as $$
declare
c cursor(r1 integer, r2 integer)
for select * from generate_series(r1,r2) i;
c2 cursor
for select * from generate_series(41,43) i;
begin
for r in c(5,7) loop
raise notice '% from %', r.i, c;
end loop;
-- again, to test if cursor was closed properly
for r in c(9,10) loop
raise notice '% from %', r.i, c;
end loop;
-- and test a parameterless cursor
for r in c2 loop
raise notice '% from %', r.i, c2;
end loop;
-- and try it with a hand-assigned name
raise notice 'after loop, c2 = %', c2;
c2 := 'special_name';
for r in c2 loop
raise notice '% from %', r.i, c2;
end loop;
raise notice 'after loop, c2 = %', c2;
-- and try it with a generated name
-- (which we can't show in the output because it's variable)
c2 := null;
for r in c2 loop
raise notice '%', r.i;
end loop;
raise notice 'after loop, c2 = %', c2;
return;
end;
$$ language plpgsql;
select forc01();
-- try updating the cursor's current row
create temp table forc_test as
select n as i, n as j from generate_series(1,10) n;
create or replace function forc01() returns void as $$
declare
c cursor for select * from forc_test;
begin
for r in c loop
raise notice '%, %', r.i, r.j;
update forc_test set i = i * 100, j = r.j * 2 where current of c;
end loop;
end;
$$ language plpgsql;
select forc01();
select * from forc_test;
drop function forc01();
-- fail because cursor has no query bound to it
create or replace function forc_bad() returns void as $$
declare
c refcursor;
begin
for r in c loop
raise notice '%', r.i;
end loop;
end;
$$ language plpgsql;
Markdown is supported
0% or
You are about to add 0 people to the discussion. Proceed with caution.
Finish editing this message first!
Please register or to comment