CREATE PROCEDURE v11
Name
CREATE PROCEDURE
-- define a new stored procedure.
Synopsis
Description
CREATE PROCEDURE
defines a new stored procedure. CREATE OR REPLACE PROCEDURE
will either create a new procedure, or replace an existing definition.
If a schema name is included, then the procedure is created in the specified schema. Otherwise it is created in the current schema. The name of the new procedure must not match any existing procedure with the same input argument types in the same schema. However, procedures of different input argument types may share a name (this is called overloading). (Overloading of procedures is an Advanced Server feature - overloading of stored, standalone procedures is not compatible with Oracle databases.)
To update the definition of an existing procedure, use CREATE OR REPLACE PROCEDURE
. It is not possible to change the name or argument types of a procedure this way (if you tried, you would actually be creating a new, distinct procedure). When using OUT
parameters, you cannot change the types of any OUT
parameters except by dropping the procedure.
Parameters
name
name
is the identifier of the procedure.
parameters
parameters
is a list of formal parameters.
declarations
declarations
are variable, cursor, type, or subprogram declarations. If subprogram declarations are included, they must be declared after all other variable, cursor, and type declarations.
statements
statements
are SPL program statements (the BEGIN - END
block may contain an EXCEPTION
section).
IMMUTABLE
STABLE
VOLATILE
These attributes inform the query optimizer about the behavior of the procedure; you can specify only one choice. VOLATILE
is the default behavior.
IMMUTABLE
indicates that the procedure cannot modify the database and always reaches the same result when given the same argument values; it does not do database lookups or otherwise use information not directly present in its argument list. If you include this clause, any call of the procedure with all-constant arguments can be immediately replaced with the procedure value.STABLE
indicates that the procedure cannot modify the database, and that within a single table scan, it will consistently return the same result for the same argument values, but that its result could change across SQL statements. This is the appropriate selection for procedures that depend on database lookups, parameter variables (such as the current time zone), etc.VOLATILE
indicates that the procedure value can change even within a single table scan, so no optimizations can be made. Please note that any function that has side-effects must be classified volatile, even if its result is quite predictable, to prevent calls from being optimized away.
DETERMINISTIC
DETERMINISTIC
is a synonym for IMMUTABLE
. A DETERMINISTIC
procedure cannot modify the database and always reaches the same result when given the same argument values; it does not do database lookups or otherwise use information not directly present in its argument list. If you include this clause, any call of the procedure with all-constant arguments can be immediately replaced with the procedure value.
[ NOT ] LEAKPROOF
A LEAKPROOF
procedure has no side effects, and reveals no information about the values used to call the procedure.
CALLED ON NULL INPUT
RETURNS NULL ON NULL INPUT
STRICT
CALLED ON NULL INPUT
(the default) indicates that the procedure will be called normally when some of its arguments areNULL
. It is the author's responsibility to check forNULL
values if necessary and respond appropriately.RETURNS NULL ON NULL INPUT
orSTRICT
indicates that the procedure always returnsNULL
whenever any of its arguments areNULL
. If these clauses are specified, the procedure is not executed when there areNULL
arguments; instead aNULL
result is assumed automatically.
[ EXTERNAL ] SECURITY DEFINER
SECURITY DEFINER
specifies that the procedure will execute with the privileges of the user that created it; this is the default. The key word EXTERNAL
is allowed for SQL conformance, but is optional.
[ EXTERNAL ] SECURITY INVOKER
The SECURITY INVOKER
clause indicates that the procedure will execute with the privileges of the user that calls it. The key word EXTERNAL
is allowed for SQL conformance, but is optional.
AUTHID DEFINER
AUTHID CURRENT_USER
The
AUTHID DEFINER
clause is a synonym for[EXTERNAL] SECURITY DEFINER
. If theAUTHID
clause is omitted or ifAUTHID DEFINER
is specified, the rights of the procedure owner are used to determine access privileges to database objects.The
AUTHID CURRENT_USER
clause is a synonym for[EXTERNAL] SECURITY INVOKER
. IfAUTHID CURRENT_USER
is specified, the rights of the current user executing the procedure are used to determine access privileges.
PARALLEL { UNSAFE | RESTRICTED | SAFE }
The PARALLEL
clause enables the use of parallel sequential scans (parallel mode). A parallel sequential scan uses multiple workers to scan a relation in parallel during a query in contrast to a serial sequential scan.
When set to
UNSAFE
, the procedure cannot be executed in parallel mode. The presence of such a procedure forces a serial execution plan. This is the default setting if thePARALLEL
clause is omitted.When set to
RESTRICTED
, the procedure can be executed in parallel mode, but the execution is restricted to the parallel group leader. If the qualification for any particular relation has anything that is parallel restricted, that relation won't be chosen for parallelism.When set to
SAFE
, the procedure can be executed in parallel mode with no restriction.
COST execution_cost
execution_cost
is a positive number giving the estimated execution cost for the procedure, in units of cpu_operator_cost
. If the procedure returns a set, this is the cost per returned row. Larger values cause the planner to try to avoid evaluating the function more often than necessary.
ROWS result_rows
result_rows
is a positive number giving the estimated number of rows that the planner should expect the procedure to return. This is only allowed when the procedure is declared to return a set. The default assumption is 1000 rows.
SET configuration_parameter { TO value | = value | FROM CURRENT }
The SET
clause causes the specified configuration parameter to be set to the specified value when the procedure is entered, and then restored to its prior value when the procedure exits. SET FROM CURRENT
saves the session's current value of the parameter as the value to be applied when the procedure is entered.
If a SET
clause is attached to a procedure, then the effects of a SET LOCAL
command executed inside the procedure for the same variable are restricted to the procedure; the configuration parameter's prior value is restored at procedure exit. An ordinary SET
command (without LOCAL
) overrides the SET
clause, much as it would do for a previous SET LOCAL
command, with the effects of such a command persisting after procedure exit, unless the current transaction is rolled back.
PRAGMA AUTONOMOUS_TRANSACTION
PRAGMA AUTONOMOUS_TRANSACTION
is the directive that sets the procedure as an autonomous transaction.
Note
- The
STRICT
,LEAKPROOF
,PARALLEL
,COST
,ROWS
andSET
keywords provide extended functionality for Advanced Server and are not supported by Oracle. - The
IMMUTABLE
,STABLE
,STRICT
,LEAKPROOF
,COST
,ROWS
andPARALLEL { UNSAFE | RESTRICTED | SAFE }
attributes are only supported for EDB SPL procedures. - By default, stored procedures are created as
SECURITY DEFINERS
; stored procedures defined in plpgsql are created asSECURITY INVOKERS
.
Examples
The following procedure lists the employees in the emp
table:
The following procedure uses IN OUT
and OUT
arguments to return an employee’s number, name, and job based upon a search using first, the given employee number, and if that is not found, then using the given name. An anonymous block calls the procedure.
The following example demonstrates using the AUTHID DEFINER
and SET
clauses in a procedure declaration. The update_salary
procedure conveys the privileges of the role that defined the procedure to the role that is calling the procedure (while the procedure executes):
Include the SET
clause to set the procedure's search path to public
and the work memory to 1MB
. Other procedures, functions and objects will not be affected by these settings.
In this example, the AUTHID DEFINER
clause temporarily grants privileges to a role that might otherwise not be allowed to execute the statements within the procedure. To instruct the server to use the privileges associated with the role invoking the procedure, replace the AUTHID DEFINER
clause with the AUTHID CURRENT_USER
clause.
See Also