Commit 3d1e01ca authored by Tom Lane's avatar Tom Lane

Support INSERT/UPDATE/DELETE RETURNING in plpgsql, with rowcount checking

as per yesterday's proposal.  Also make things a tad more orthogonal by
adding the recent STRICT addition to EXECUTE INTO.
Jonah Harris and Tom Lane
parent 29fa0513
This diff is collapsed.
This diff is collapsed.
This diff is collapsed.
......@@ -8,7 +8,7 @@
*
*
* IDENTIFICATION
* $PostgreSQL: pgsql/src/pl/plpgsql/src/pl_funcs.c,v 1.53 2006/06/12 16:45:30 momjian Exp $
* $PostgreSQL: pgsql/src/pl/plpgsql/src/pl_funcs.c,v 1.54 2006/08/14 21:14:41 tgl Exp $
*
*-------------------------------------------------------------------------
*/
......@@ -439,8 +439,6 @@ plpgsql_stmt_typename(PLpgSQL_stmt *stmt)
return "for with integer loopvar";
case PLPGSQL_STMT_FORS:
return "for over select rows";
case PLPGSQL_STMT_SELECT:
return "select into variables";
case PLPGSQL_STMT_EXIT:
return "exit";
case PLPGSQL_STMT_RETURN:
......@@ -485,7 +483,6 @@ 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_select(PLpgSQL_stmt_select *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);
......@@ -537,9 +534,6 @@ dump_stmt(PLpgSQL_stmt *stmt)
case PLPGSQL_STMT_FORS:
dump_fors((PLpgSQL_stmt_fors *) stmt);
break;
case PLPGSQL_STMT_SELECT:
dump_select((PLpgSQL_stmt_select *) stmt);
break;
case PLPGSQL_STMT_EXIT:
dump_exit((PLpgSQL_stmt_exit *) stmt);
break;
......@@ -731,29 +725,6 @@ dump_fors(PLpgSQL_stmt_fors *stmt)
printf(" ENDFORS\n");
}
static void
dump_select(PLpgSQL_stmt_select *stmt)
{
dump_ind();
printf("SELECT ");
dump_expr(stmt->query);
printf("\n");
dump_indent += 2;
if (stmt->rec != NULL)
{
dump_ind();
printf(" target = %d %s\n", stmt->rec->recno, stmt->rec->refname);
}
if (stmt->row != NULL)
{
dump_ind();
printf(" target = %d %s\n", stmt->row->rowno, stmt->row->refname);
}
dump_indent -= 2;
}
static void
dump_open(PLpgSQL_stmt_open *stmt)
{
......@@ -891,6 +862,23 @@ dump_execsql(PLpgSQL_stmt_execsql *stmt)
printf("EXECSQL ");
dump_expr(stmt->sqlstmt);
printf("\n");
dump_indent += 2;
if (stmt->rec != NULL)
{
dump_ind();
printf(" INTO%s target = %d %s\n",
stmt->strict ? " STRICT" : "",
stmt->rec->recno, stmt->rec->refname);
}
if (stmt->row != NULL)
{
dump_ind();
printf(" INTO%s target = %d %s\n",
stmt->strict ? " STRICT" : "",
stmt->row->rowno, stmt->row->refname);
}
dump_indent -= 2;
}
static void
......@@ -905,12 +893,16 @@ dump_dynexecute(PLpgSQL_stmt_dynexecute *stmt)
if (stmt->rec != NULL)
{
dump_ind();
printf(" target = %d %s\n", stmt->rec->recno, stmt->rec->refname);
printf(" INTO%s target = %d %s\n",
stmt->strict ? " STRICT" : "",
stmt->rec->recno, stmt->rec->refname);
}
else if (stmt->row != NULL)
if (stmt->row != NULL)
{
dump_ind();
printf(" target = %d %s\n", stmt->row->rowno, stmt->row->refname);
printf(" INTO%s target = %d %s\n",
stmt->strict ? " STRICT" : "",
stmt->row->rowno, stmt->row->refname);
}
dump_indent -= 2;
}
......
......@@ -8,7 +8,7 @@
*
*
* IDENTIFICATION
* $PostgreSQL: pgsql/src/pl/plpgsql/src/plpgsql.h,v 1.78 2006/08/08 19:15:09 tgl Exp $
* $PostgreSQL: pgsql/src/pl/plpgsql/src/plpgsql.h,v 1.79 2006/08/14 21:14:41 tgl Exp $
*
*-------------------------------------------------------------------------
*/
......@@ -80,7 +80,6 @@ enum
PLPGSQL_STMT_WHILE,
PLPGSQL_STMT_FORI,
PLPGSQL_STMT_FORS,
PLPGSQL_STMT_SELECT,
PLPGSQL_STMT_EXIT,
PLPGSQL_STMT_RETURN,
PLPGSQL_STMT_RETURN_NEXT,
......@@ -428,17 +427,6 @@ typedef struct
} PLpgSQL_stmt_dynfors;
typedef struct
{ /* SELECT ... INTO statement */
int cmd_type;
int lineno;
bool strict;
PLpgSQL_rec *rec;
PLpgSQL_row *row;
PLpgSQL_expr *query;
} PLpgSQL_stmt_select;
typedef struct
{ /* OPEN a curvar */
int cmd_type;
......@@ -510,6 +498,12 @@ typedef struct
int cmd_type;
int lineno;
PLpgSQL_expr *sqlstmt;
bool mod_stmt; /* is the stmt INSERT/UPDATE/DELETE? */
/* note: mod_stmt is set when we plan the query */
bool into; /* INTO supplied? */
bool strict; /* INTO STRICT flag */
PLpgSQL_rec *rec; /* INTO target, if record */
PLpgSQL_row *row; /* INTO target, if row */
} PLpgSQL_stmt_execsql;
......@@ -517,9 +511,11 @@ typedef struct
{ /* Dynamic SQL string to execute */
int cmd_type;
int lineno;
PLpgSQL_rec *rec; /* INTO record or row variable */
PLpgSQL_row *row;
PLpgSQL_expr *query;
PLpgSQL_expr *query; /* string expression */
bool into; /* INTO supplied? */
bool strict; /* INTO STRICT flag */
PLpgSQL_rec *rec; /* INTO target, if record */
PLpgSQL_row *row; /* INTO target, if row */
} PLpgSQL_stmt_dynexecute;
......
......@@ -9,7 +9,7 @@
*
*
* IDENTIFICATION
* $PostgreSQL: pgsql/src/pl/plpgsql/src/scan.l,v 1.53 2006/08/14 00:46:53 tgl Exp $
* $PostgreSQL: pgsql/src/pl/plpgsql/src/scan.l,v 1.54 2006/08/14 21:14:42 tgl Exp $
*
*-------------------------------------------------------------------------
*/
......@@ -137,6 +137,7 @@ get { return K_GET; }
if { return K_IF; }
in { return K_IN; }
info { return K_INFO; }
insert { return K_INSERT; }
into { return K_INTO; }
is { return K_IS; }
log { return K_LOG; }
......@@ -154,7 +155,6 @@ result_oid { return K_RESULT_OID; }
return { return K_RETURN; }
reverse { return K_REVERSE; }
row_count { return K_ROW_COUNT; }
select { return K_SELECT; }
strict { return K_STRICT; }
then { return K_THEN; }
to { return K_TO; }
......
......@@ -2048,6 +2048,7 @@ select * from foo;
20
(2 rows)
drop table foo;
-- Test for pass-by-ref values being stored in proper context
create function test_variable_storage() returns text as $$
declare x text;
......@@ -2794,3 +2795,142 @@ select multi_datum_use(42);
t
(1 row)
--
-- Test STRICT limiter in both planned and EXECUTE invocations.
-- Note that a data-modifying query is quasi strict (disallow multi rows)
-- by default in the planned case, but not in EXECUTE.
--
create temp table foo (f1 int, f2 int);
insert into foo values (1,2), (3,4);
create or replace function footest() returns void as $$
declare x record;
begin
-- should work
insert into foo values(5,6) returning * into x;
raise notice 'x.f1 = %, x.f2 = %', x.f1, x.f2;
end$$ language plpgsql;
select footest();
NOTICE: x.f1 = 5, x.f2 = 6
footest
---------
(1 row)
create or replace function footest() returns void as $$
declare x record;
begin
-- should fail due to implicit strict
insert into foo values(7,8),(9,10) returning * into 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 4 at SQL statement
create or replace function footest() returns void as $$
declare x record;
begin
-- should work
execute 'insert into foo values(5,6) returning *' into x;
raise notice 'x.f1 = %, x.f2 = %', x.f1, x.f2;
end$$ language plpgsql;
select footest();
NOTICE: x.f1 = 5, x.f2 = 6
footest
---------
(1 row)
create or replace function footest() returns void as $$
declare x record;
begin
-- this should work since EXECUTE isn't as picky
execute 'insert into foo values(7,8),(9,10) returning *' into x;
raise notice 'x.f1 = %, x.f2 = %', x.f1, x.f2;
end$$ language plpgsql;
select footest();
NOTICE: x.f1 = 7, x.f2 = 8
footest
---------
(1 row)
select * from foo;
f1 | f2
----+----
1 | 2
3 | 4
5 | 6
5 | 6
7 | 8
9 | 10
(6 rows)
create or replace function footest() returns void as $$
declare x record;
begin
-- should work
select * from foo where f1 = 3 into strict x;
raise notice 'x.f1 = %, x.f2 = %', x.f1, x.f2;
end$$ language plpgsql;
select footest();
NOTICE: x.f1 = 3, x.f2 = 4
footest
---------
(1 row)
create or replace function footest() returns void as $$
declare x record;
begin
-- should fail, no rows
select * from foo where f1 = 0 into strict x;
raise notice 'x.f1 = %, x.f2 = %', x.f1, x.f2;
end$$ language plpgsql;
select footest();
ERROR: query returned no rows
CONTEXT: PL/pgSQL function "footest" line 4 at SQL statement
create or replace function footest() returns void as $$
declare x record;
begin
-- should fail, too many rows
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 4 at SQL statement
create or replace function footest() returns void as $$
declare x record;
begin
-- should work
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();
NOTICE: x.f1 = 3, x.f2 = 4
footest
---------
(1 row)
create or replace function footest() returns void as $$
declare x record;
begin
-- should fail, no rows
execute 'select * from foo where f1 = 0' into strict x;
raise notice 'x.f1 = %, x.f2 = %', x.f1, x.f2;
end$$ language plpgsql;
select footest();
ERROR: query returned no rows
CONTEXT: PL/pgSQL function "footest" line 4 at execute statement
create or replace function footest() returns void as $$
declare x record;
begin
-- should fail, too many rows
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 4 at execute statement
drop function footest();
......@@ -1777,6 +1777,8 @@ reset statement_timeout;
select * from foo;
drop table foo;
-- Test for pass-by-ref values being stored in proper context
create function test_variable_storage() returns text as $$
declare x text;
......@@ -2324,3 +2326,117 @@ begin
end$$ language plpgsql;
select multi_datum_use(42);
--
-- Test STRICT limiter in both planned and EXECUTE invocations.
-- Note that a data-modifying query is quasi strict (disallow multi rows)
-- by default in the planned case, but not in EXECUTE.
--
create temp table foo (f1 int, f2 int);
insert into foo values (1,2), (3,4);
create or replace function footest() returns void as $$
declare x record;
begin
-- should work
insert into foo values(5,6) returning * into 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
-- should fail due to implicit strict
insert into foo values(7,8),(9,10) returning * into 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
-- should work
execute 'insert into foo values(5,6) returning *' into 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
-- this should work since EXECUTE isn't as picky
execute 'insert into foo values(7,8),(9,10) returning *' into x;
raise notice 'x.f1 = %, x.f2 = %', x.f1, x.f2;
end$$ language plpgsql;
select footest();
select * from foo;
create or replace function footest() returns void as $$
declare x record;
begin
-- should work
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
-- should fail, no rows
select * from foo where f1 = 0 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
-- should fail, too many rows
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
-- should work
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 $$
declare x record;
begin
-- should fail, no rows
execute 'select * from foo where f1 = 0' 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
-- should fail, too many rows
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();
drop function footest();
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