HomeMogDBMogDB StackUqbar
v2.1

Documentation:v2.1

Supported Versions:

CREATE PROCEDURE

Function

CREATE PROCEDURE 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 stored procedure has output parameters, the SELECT statement uses the default values of the output parameters when calling the procedure. When the CALL statement calls the stored procedure or a non-overloaded function, output parameters must be specified. When the CALL statement calls an overloaded PACKAGE function, it can use the default values of the output parameters. For details, see examples in CALL.

  • A stored procedure with the PACKAGE attribute can use overloaded functions.

  • When you create a procedure, you cannot insert aggregate functions or other functions out of the average function.

  • When calling stored procedures without parameters inside another stored procedure, you can omit brackets and call stored procedures using their names directly.

  • 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.

Syntax

CreateProcedure ::= CREATE [ OR REPLACE ] PROCEDURE procedure_name
    [ ( {[ argmode ] [ argname ] 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

Parameter Description

  • 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. It must comply with the naming convention.

  • argmode

    Specifies the mode of an argument.

    img NOTICE: 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. It must comply with the naming convention.

  • 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

  • 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.

    img NOTICE: When you create a user, or perform other operations requiring password input in a stored procedure, the system catalog and CSV log record the password in plaintext. Therefore, you are advised not to perform such operations in the stored procedure.

img NOTE: No specific order is applied to argument_name and argmode. The following order is advised: argument_name, argmode, and argument_type.

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.
Copyright © 2011-2024 www.enmotech.com All rights reserved.