Updated on 2024-08-20 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.
  • When a stored procedure is created, a write lock is added only to the CREATE stored procedure or package, and a read lock is added only to the functions and packages on which the functions depend during compilation and execution.
  • 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.
  • When the function is called by SELECT or CALL, an argument must be provided in the output parameter. The argument does not take effect.
  • A stored procedure with the PACKAGE attribute can use overloaded functions.
  • Do not create an overloaded stored procedure with different parameter names but same stored procedure name and parameter list type.
  • When an overloaded stored procedure is called, the variable type must be specified.
  • Do not create a stored procedure that has the same name and parameter list as the function.
  • Do not overload stored procedures with different default values.
  • Only the in, out, and inout parameters of the stored procedure cannot be reloaded after the GUC parameter behavior_compat_options='proc_outparam_override' is enabled. They can be overloaded after the parameter is disabled.
  • A-compatible functions are created for A-compatible databases and PG-compatible functions are created for PG-compatible databases. Hybrid creation is not recommended.
  • If a function supports overloading, you need to add the keyword PACKAGE.
  • If an undeclared variable is used in a stored procedure, an error is reported when the stored procedure is called.
  • When you create a procedure, you cannot insert aggregate functions or other functions out of the average function.
  • The stored procedure does not support operations that will return a set.
  • When stored procedures without parameters are called in another stored procedure, you can omit brackets and call stored procedures using their names directly.
  • When other functions with output parameters are called in a stored procedure and an assignment expression, set the GUC parameter set behavior_compat_options to 'proc_outparam_override', define variables of the same type as the output parameters in advance, and use the variables as output parameters to call other functions with output parameters for the output parameters to take effect. Otherwise, the output parameters of the called function will be ignored.
  • If the out parameter is used as the output parameter in an expression, the expression does not take effect in the following scenarios: The execute immediate sqlv using func syntax is used to execute a function. The select func into syntax is used to execute a function. DML statements such as INSERT and UPDATE are used to execute a function. When a function with the out output parameter is used as an input parameter, that is, fun (func (out b), a), the out b parameter does not take effect.
  • 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 with the CREATE ANY FUNCTION permission can create or replace stored procedures in the user schemas.
  • out/inout 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 the 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 a stored procedure is created, it depends on an undefined object. If behavior_compat_options is set to 'plpgsql_dependency', the creation can be executed, and a warning message is displayed. If behavior_compat_options is not set to 'plpgsql_dependency', the creation cannot be executed.
  • When separation of duties is enabled, the stored procedure of the definer permission can be re-created only by the current user.
  • 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.
  • When the complex function is called in a stored procedure, for example, func(x).a, a composite type is returned. Cross-schema call is supported, but the database.schema.package.func(x).b call is not supported.
  • When a stored procedure with the out parameter is called, you can set the GUC parameter set behavior_compat_options to 'proc_outparam_transfer_length' to transfer the parameter length. The specifications and constraints are as follows:
    1. The following types are supported: CHAR(n), CHARACTER(n), NCHAR(n), VARCHAR(n), VARYING(n), VARCHAR2(n), and NVARCHAR2(n).
    2. If the out parameter does not take effect (for example, perform), the length does not need to be transferred.
    3. The following types do not support precision transfer: NUMERIC, DECIMAL, NUMBER, FLOAT, DEC, INTEGER, TIME, TIMESTAMP, INTERVAL, TIME WITH TIME ZONE, TIMESTAMP WITH TIME ZONE, TIME WITHOUT TIME ZONE, and TIMESTAMP WITHOUT TIME ZONE.
    4. The parameter length can be transferred regardless of whether the GUC parameter set behavior_compat_options is set to proc_outparam_override.
    5. To transfer the length of elements of the collection type and the length of elements of the array type nested by the collection type, you need to set the GUC parameter behavior_compat_options to tableof_elem_constraints.
  • Functions contain syntaxes and functions that use GUC parameters to control features. If GUC parameters are modified in a session, the function may retain the behavior before the modification. Therefore, exercise caution when modifying GUC parameters.

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

    When creating a function with the same name as a system function, you need to specify the schema of the function.

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

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

  • expression

    Specifies the default expression of a parameter.

    • If a_format_version is set to 10c and a_format_dev_version is set to s2, the default expression is not supported when the parameter is in INOUT mode.
    • It is recommended that you define all default parameters after all non-default parameters.
    • If a function with default parameters is called, input parameters are added to the function from left to right. If inputs of non-default parameters are missing, an error is reported.
    • If proc_uncheck_default_param is enabled and a function with default parameters is called, input parameters are added to the function from left to right. The number of defaulted inputs depends on the number of default parameters. If an input of a non-default parameter is missing, the previous default value is used to fill this parameter.
    • When a_format_version is set to 10c, a_format_dev_version is set to s1, proc_outparam_override is disabled, and the function parameters include the output parameter out and default, the default value cannot be used.
  • 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.

Examples

  • Create a stored procedure.
    -- Create a stored procedure and print the sum of the input parameters.
    gaussdb=# CREATE OR REPLACE PROCEDURE proc_add(i int, j int)
    AS 
    BEGIN
         dbe_output.print_line('result is: '|| i+j);
    END;
    /
    
    -- Use CALL to call a stored procedure.
    gaussdb=# CALL proc_add(16,17);
    
    -- Use a program block to call a stored procedure.
    gaussdb=# BEGIN
        proc_add(16,17);
    END;
    /
    
    -- Delete.
    gaussdb=# DROP PROCEDURE proc_add;
  • Create a stored procedure whose parameter model is VARIADIC.
    -- Create the stored procedure pro_variadic.
    gaussdb=# CREATE OR REPLACE PROCEDURE pro_variadic (var1 VARCHAR2(10) DEFAULT 'hello!',var4 VARIADIC int4[])
    AS
    BEGIN
        dbe_output.print_line(var1);
    END;
    /
    
    -- Execute the stored procedure.
    gaussdb=# SELECT pro_variadic(var1=>'hello', VARIADIC var4=> array[1,2,3,4]);
    
    -- Delete.
    gaussdb=# DROP PROCEDURE pro_variadic;
  • Parameter models: IN and OUT
    • IN (default) indicates that the parameter is an input parameter.
    • OUT indicates that the parameter is an output parameter.
    • IN OUT indicates that the parameter is an input and output parameter
    -- Create the stored procedure proc_add1. num1 and num2 are input parameters, and num3 is an output parameter.
    gaussdb=# CREATE PROCEDURE proc_add1 (num1 in int, num2 in int, num3 out int)
    AS
    BEGIN 
        num3 := num1 + num2;
    END;
    /
    
    -- Use a program block to call the stored procedure and use variable c to receive the parameters sent by the stored procedure.
    gaussdb=# DECLARE 
        a int := 20;
        b int := 32;
        c int := 0;
    BEGIN 
        proc_add1(a,b,c);
        dbe_output.put_line(c);
    END; 
    /
    
    -- Delete.
    gaussdb=# DROP PROCEDURE proc_add1;

Helpful Links

ALTER PROCEDURE and 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.