Updated on 2024-05-07 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.
  • When the function is called by SELECT or CALL, an argument must be provided in the output parameter. The argument does not take effect.
  • Do not create an overloaded stored procedure with different parameter names but same stored procedure name and parameter list type.
  • 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 is set to 'proc_outparam_override'. They can be reloaded after the parameter is disabled.
  • When an overloaded stored procedure is called, the variable type must be specified.
  • 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.
  • If a function is defined as IMMUTABLE or SHIPPABLE, avoid INSERT, UPDATE, DELETE, MERGE, and DDL operations in the function because the CN needs to determine the execution node for these operations. Otherwise, an error may occur.
  • 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.
  • 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.
  • Users granted with the CREATE ANY FUNCTION permission can create or replace stored procedures in the user schemas.
  • 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'.
  • 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, stored procedures with the definer specified can be rebuilt only by the current user. Only the initial user can alter the stored procedures to other users.
  • 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.
  • If the out parameter is used as the output parameter in an expression, the expression does not take effect in the following scenarios: (a) The execute immediate sqlv using func syntax is used to execute a function. (b) The select func into syntax is used to execute a function. (c) DML statements such as INSERT and UPDATE are used to execute a function. (d) The select where a=func() statement is used. (e) 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.
  • When a stored procedure with the out parameter is called, you can set the GUC parameter set behavior_compat_options = '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.

Syntax

 1
 2
 3
 4
 5
 6
 7
 8
 9
10
11
12
13
14
gaussdb=# CREATE [ OR REPLACE ] PROCEDURE procedure_name
    [ ( {[ argname ] [ argmode ] argtype [ { DEFAULT | := | = } expression ]}[,...]) ]
    [
       { IMMUTABLE | STABLE | VOLATILE }
       | { SHIPPABLE | NOT SHIPPABLE }
       | [ 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.

  • 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 parameter of the OUT mode can be followed by VARIADIC. The parameters of OUT and INOUT cannot be used in procedure definition of RETURNS TABLE.

  • argname

    Specifies the argument name.

    Value range: a string. It must comply with the naming convention.

  • argtype

    Specifies the type of an argument. You can use %ROWTYPE to indirectly reference the type of a table.

    Value range: a valid data type

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

 1
 2
 3
 4
 5
 6
 7
 8
 9
10
11
12
13
14
15
16
17
18
19
20
21
22
23
24
25
26
27
28
29
30
31
32
33
34
35
36
37
38
39
40
41
42
43
44
-- Create a stored procedure.
gaussdb=# CREATE OR REPLACE PROCEDURE prc_add
(
    param1    IN   INTEGER,
    param2    IN OUT  INTEGER
)
AS
BEGIN
   param2:= param1 + param2;
   dbe_output.print_line('result is: '||to_char(param2));
END;
/

-- Call the stored procedure.
gaussdb=# SELECT prc_add(2,3);

-- Create a stored procedure whose parameter type is 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]);

-- Create a stored procedure with the permission of the user who calls it.
gaussdb=# CREATE TABLE tb1(a integer);
gaussdb=# CREATE PROCEDURE insert_data(v integer)      
SECURITY INVOKER
AS
BEGIN
    INSERT INTO tb1 VALUES(v);
END;
/

-- Call the stored procedure.
gaussdb=# CALL insert_data(1);

-- Delete the stored procedure.
gaussdb=# DROP PROCEDURE prc_add;
gaussdb=# DROP PROCEDURE pro_variadic;
gaussdb=# DROP PROCEDURE insert_data;

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.