Updated on 2025-07-22 GMT+08:00

CREATE PROCEDURE

Description

Creates a stored procedure.

Precautions

  • If the parameters or return values of a stored procedure have precision, the precision is not checked.
  • When creating a stored procedure, you are advised to explicitly specify the schemas of all operations on table objects in the stored procedure definition. Otherwise, the stored procedure may fail to be executed.
  • current_schema and search_path specified by SET during stored procedure creation are invalid. search_path and current_schema before and after function execution should be the same.
  • If a SELECT statement calls a stored procedure with output parameters, output parameters cannot be specified. When a CALL statement calls a stored procedure involving a non-overloaded function, output parameters must be specified. When a CALL statement calls an overloaded PACKAGE function, the output parameters may not be specified. For details, see examples in CALL.
  • A stored procedure with the PACKAGE attribute can use overloaded functions.
  • When you create a procedure, you cannot nest average functions within aggregate or other functions.
  • When stored procedures without parameters are called in another stored procedure, you can omit brackets and call stored procedures using their names directly.
  • When functions with output parameters are called in a stored procedure which is an assignment expression, you can omit the output parameters of the called functions.
  • The stored procedure supports viewing, exporting, and importing parameter comments.
  • The stored procedure supports viewing, exporting, and importing parameter comments between IS/AS and plsql_body.
  • The default permission on a stored procedure is SECURITY INVOKER. To change the default permission to SECURITY DEFINER, set the GUC parameter behavior_compat_options to 'plsql_security_definer'.
  • Users granted the CREATE ANY FUNCTION permission can create or replace stored procedures in the user schemas.
  • An out or inout parameter must be set to a variable but not a constant.
  • In a centralized environment, if you want to call a stored procedure with the same in parameters but different out parameters, you need to set the GUC parameter behavior_compat_options to 'proc_outparam_override'. After the parameter is enabled, you must add out parameters no matter whether you use the SELECT or CALL statement to call the stored procedure. After the parameter is enabled, you cannot use perform to call a stored procedure or function.
  • When an overloaded stored procedure is called, the variable type must be specified.
  • If a stored procedure with the definer specified is created in a schema of another user, the stored procedure will be executed by another user, which may cause unauthorized operations. Therefore, exercise caution when performing this operation.

Syntax

CREATE [ OR REPLACE ] PROCEDURE procedure_name
    [ ( {[ argname ] [ argmode ] argtype [ { DEFAULT | := | = } expression ]}[,...]) ]
    [
       { IMMUTABLE | STABLE | VOLATILE }
       | { SHIPPABLE | NOT SHIPPABLE }
       | {PACKAGE}
       | [ NOT ] LEAKPROOF
       | { CALLED ON NULL INPUT | RETURNS NULL ON NULL INPUT | STRICT }
       | {[ EXTERNAL ] SECURITY INVOKER | [ EXTERNAL ] SECURITY DEFINER | AUTHID DEFINER | AUTHID CURRENT_USER}
       | COST execution_cost
       | SET configuration_parameter { TO value | = value | FROM CURRENT }
    ][ ... ]
 { IS | AS } 
plsql_body 
/

Parameters

  • OR REPLACE

    Replaces the original definition when two stored procedures are with the same name.

  • procedure_name

    Specifies the name of the stored procedure that is created (optionally with schema names).

    Value range: a string that complies with the Identifier Naming Conventions.

  • argmode

    Specifies the mode of an argument.

    VARIADIC specifies parameters of the array type.

    Value range: IN, OUT, INOUT, and VARIADIC. The default value is IN. Only the parameters in OUT mode can follow the VARIADIC parameter.

  • argname

    Specifies the argument name.

    Value range: a string that complies with the Identifier Naming Conventions.

  • argtype

    Specifies the type of an argument. %TYPE or %ROWTYPE can be used to indirectly reference a variable or table type. For details, see Variable Definition Statements.

    Value range: a valid data type.

    In PROCEDURE argtype outside PACKAGE, %TYPE cannot reference the type of the PACKAGE variable.

  • expression

    Specifies the default expression of a parameter.

    • It is recommended that you define all default parameters after all non-default parameters.
  • configuration_parameter
    • value

      Sets the specified configuration parameter to a specified value. If the value is DEFAULT, the default setting is used in the new session. OFF disables the setting.

      Value range: a string.

      • DEFAULT
      • OFF
      • Specified default value
    • from current

      Uses the value of configuration_parameter of the current session.

  • IMMUTABLE, STABLE,...

    Specifies a constraint. The function of each parameter is similar to that of CREATE FUNCTION. For details, see CREATE FUNCTION.

  • plsql_body

    Specifies the PL/SQL stored procedure body.

    When you perform password-related operations, such as user creation, password change, and encryption/decryption, in a stored procedure, the password will be recorded in the system catalogs and logs in plaintext. To prevent sensitive information leakage, you are advised not to perform password-related operations in a stored procedure.

No specific order is applied to argname and argname. The following order is advised: argname, argmode, and argtype.

Helpful Links

DROP PROCEDURE

Suggestions

  • analyse | analyze
    • Do not run ANALYZE in a transaction or anonymous block.
    • Do not run ANALYZE in a function or stored procedure.