Updated on 2025-02-27 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.
  • 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 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.
  • 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'.
  • 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

 1
 2
 3
 4
 5
 6
 7
 8
 9
10
11
12
13
14
15
openGauss=# 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 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 of OUT 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 that complies with the Identifier Naming Conventions.

  • argtype

    Specifies the type of an argument. You can use %ROWTYPE to indirectly reference the type of a table, or %TYPE to indirectly reference the type of a column in a table or composite type.

    Value range: a valid data type.

  • expression

    Specifies the default expression of a parameter.

    • It is recommended that you define all default parameters after all non-default parameters.
  • 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

 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
45
46
47
48
49
50
51
52
53
54
55
56
-- Create a stored procedure.
openGauss=# 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.
openGauss=# SELECT prc_add(2,3);

-- Create a stored procedure whose parameter type is VARIADIC.
openGauss=# 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.
openGauss=# 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.
openGauss=# CREATE TABLE tb1(a integer);
openGauss=#  CREATE PROCEDURE insert_data(v integer)      
SECURITY INVOKER
AS
BEGIN
    INSERT INTO tb1 VALUES(v);
END;
/

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

-- Create a stored procedure with the PACKAGE attribute.
openGauss=# create or replace procedure package_func_overload(col int, col2 out varchar)
package
as
declare
    col_type text;
begin
     col2 := '122';
         dbe_output.print_line('two varchar parameters ' || col2);
end;
/
-- Drop stored procedures.
openGauss=# DROP PROCEDURE prc_add;
openGauss=# DROP PROCEDURE pro_variadic;
openGauss=# DROP PROCEDURE insert_data;
openGauss=# DROP PROCEDURE package_func_overload;

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.