mirror of
https://git.postgresql.org/git/postgresql.git
synced 2026-02-06 12:47:35 +08:00
SQL procedures
This adds a new object type "procedure" that is similar to a function but does not have a return type and is invoked by the new CALL statement instead of SELECT or similar. This implementation is aligned with the SQL standard and compatible with or similar to other SQL implementations. This commit adds new commands CALL, CREATE/ALTER/DROP PROCEDURE, as well as ALTER/DROP ROUTINE that can refer to either a function or a procedure (or an aggregate function, as an extension to SQL). There is also support for procedures in various utility commands such as COMMENT and GRANT, as well as support in pg_dump and psql. Support for defining procedures is available in all the languages supplied by the core distribution. While this commit is mainly syntax sugar around existing functionality, future features will rely on having procedures as a separate object type. Reviewed-by: Andrew Dunstan <andrew.dunstan@2ndquadrant.com>
This commit is contained in:
@ -78,6 +78,7 @@ REGRESS = \
|
||||
plpython_spi \
|
||||
plpython_newline \
|
||||
plpython_void \
|
||||
plpython_call \
|
||||
plpython_params \
|
||||
plpython_setof \
|
||||
plpython_record \
|
||||
|
||||
35
src/pl/plpython/expected/plpython_call.out
Normal file
35
src/pl/plpython/expected/plpython_call.out
Normal file
@ -0,0 +1,35 @@
|
||||
--
|
||||
-- Tests for procedures / CALL syntax
|
||||
--
|
||||
CREATE PROCEDURE test_proc1()
|
||||
LANGUAGE plpythonu
|
||||
AS $$
|
||||
pass
|
||||
$$;
|
||||
CALL test_proc1();
|
||||
-- error: can't return non-None
|
||||
CREATE PROCEDURE test_proc2()
|
||||
LANGUAGE plpythonu
|
||||
AS $$
|
||||
return 5
|
||||
$$;
|
||||
CALL test_proc2();
|
||||
ERROR: PL/Python procedure did not return None
|
||||
CONTEXT: PL/Python procedure "test_proc2"
|
||||
CREATE TABLE test1 (a int);
|
||||
CREATE PROCEDURE test_proc3(x int)
|
||||
LANGUAGE plpythonu
|
||||
AS $$
|
||||
plpy.execute("INSERT INTO test1 VALUES (%s)" % x)
|
||||
$$;
|
||||
CALL test_proc3(55);
|
||||
SELECT * FROM test1;
|
||||
a
|
||||
----
|
||||
55
|
||||
(1 row)
|
||||
|
||||
DROP PROCEDURE test_proc1;
|
||||
DROP PROCEDURE test_proc2;
|
||||
DROP PROCEDURE test_proc3;
|
||||
DROP TABLE test1;
|
||||
@ -199,12 +199,19 @@ PLy_exec_function(FunctionCallInfo fcinfo, PLyProcedure *proc)
|
||||
error_context_stack = &plerrcontext;
|
||||
|
||||
/*
|
||||
* If the function is declared to return void, the Python return value
|
||||
* For a procedure or function declared to return void, the Python return value
|
||||
* must be None. For void-returning functions, we also treat a None
|
||||
* return value as a special "void datum" rather than NULL (as is the
|
||||
* case for non-void-returning functions).
|
||||
*/
|
||||
if (proc->result.typoid == VOIDOID)
|
||||
if (proc->is_procedure)
|
||||
{
|
||||
if (plrv != Py_None)
|
||||
ereport(ERROR,
|
||||
(errcode(ERRCODE_DATATYPE_MISMATCH),
|
||||
errmsg("PL/Python procedure did not return None")));
|
||||
}
|
||||
else if (proc->result.typoid == VOIDOID)
|
||||
{
|
||||
if (plrv != Py_None)
|
||||
ereport(ERROR,
|
||||
@ -672,7 +679,8 @@ plpython_return_error_callback(void *arg)
|
||||
{
|
||||
PLyExecutionContext *exec_ctx = PLy_current_execution_context();
|
||||
|
||||
if (exec_ctx->curr_proc)
|
||||
if (exec_ctx->curr_proc &&
|
||||
!exec_ctx->curr_proc->is_procedure)
|
||||
errcontext("while creating return value");
|
||||
}
|
||||
|
||||
|
||||
@ -389,8 +389,14 @@ plpython_error_callback(void *arg)
|
||||
PLyExecutionContext *exec_ctx = PLy_current_execution_context();
|
||||
|
||||
if (exec_ctx->curr_proc)
|
||||
errcontext("PL/Python function \"%s\"",
|
||||
PLy_procedure_name(exec_ctx->curr_proc));
|
||||
{
|
||||
if (exec_ctx->curr_proc->is_procedure)
|
||||
errcontext("PL/Python procedure \"%s\"",
|
||||
PLy_procedure_name(exec_ctx->curr_proc));
|
||||
else
|
||||
errcontext("PL/Python function \"%s\"",
|
||||
PLy_procedure_name(exec_ctx->curr_proc));
|
||||
}
|
||||
}
|
||||
|
||||
static void
|
||||
|
||||
@ -189,6 +189,7 @@ PLy_procedure_create(HeapTuple procTup, Oid fn_oid, bool is_trigger)
|
||||
proc->fn_tid = procTup->t_self;
|
||||
proc->fn_readonly = (procStruct->provolatile != PROVOLATILE_VOLATILE);
|
||||
proc->is_setof = procStruct->proretset;
|
||||
proc->is_procedure = (procStruct->prorettype == InvalidOid);
|
||||
proc->src = NULL;
|
||||
proc->argnames = NULL;
|
||||
proc->args = NULL;
|
||||
@ -206,9 +207,9 @@ PLy_procedure_create(HeapTuple procTup, Oid fn_oid, bool is_trigger)
|
||||
|
||||
/*
|
||||
* get information required for output conversion of the return value,
|
||||
* but only if this isn't a trigger.
|
||||
* but only if this isn't a trigger or procedure.
|
||||
*/
|
||||
if (!is_trigger)
|
||||
if (!is_trigger && procStruct->prorettype)
|
||||
{
|
||||
Oid rettype = procStruct->prorettype;
|
||||
HeapTuple rvTypeTup;
|
||||
|
||||
@ -30,7 +30,8 @@ typedef struct PLyProcedure
|
||||
TransactionId fn_xmin;
|
||||
ItemPointerData fn_tid;
|
||||
bool fn_readonly;
|
||||
bool is_setof; /* true, if procedure returns result set */
|
||||
bool is_setof; /* true, if function returns result set */
|
||||
bool is_procedure;
|
||||
PLyObToDatum result; /* Function result output conversion info */
|
||||
PLyDatumToOb result_in; /* For converting input tuples in a trigger */
|
||||
char *src; /* textual procedure code, after mangling */
|
||||
|
||||
41
src/pl/plpython/sql/plpython_call.sql
Normal file
41
src/pl/plpython/sql/plpython_call.sql
Normal file
@ -0,0 +1,41 @@
|
||||
--
|
||||
-- Tests for procedures / CALL syntax
|
||||
--
|
||||
|
||||
CREATE PROCEDURE test_proc1()
|
||||
LANGUAGE plpythonu
|
||||
AS $$
|
||||
pass
|
||||
$$;
|
||||
|
||||
CALL test_proc1();
|
||||
|
||||
|
||||
-- error: can't return non-None
|
||||
CREATE PROCEDURE test_proc2()
|
||||
LANGUAGE plpythonu
|
||||
AS $$
|
||||
return 5
|
||||
$$;
|
||||
|
||||
CALL test_proc2();
|
||||
|
||||
|
||||
CREATE TABLE test1 (a int);
|
||||
|
||||
CREATE PROCEDURE test_proc3(x int)
|
||||
LANGUAGE plpythonu
|
||||
AS $$
|
||||
plpy.execute("INSERT INTO test1 VALUES (%s)" % x)
|
||||
$$;
|
||||
|
||||
CALL test_proc3(55);
|
||||
|
||||
SELECT * FROM test1;
|
||||
|
||||
|
||||
DROP PROCEDURE test_proc1;
|
||||
DROP PROCEDURE test_proc2;
|
||||
DROP PROCEDURE test_proc3;
|
||||
|
||||
DROP TABLE test1;
|
||||
Reference in New Issue
Block a user