Dynamically Calling Anonymous Blocks
This section describes how to execute anonymous blocks in dynamic statements. Append IN and OUT behind the EXECUTE IMMEDIATE...USING statement to input and output parameters.
Syntax
Figure 1 shows the syntax diagram.
Figure 2 shows the syntax diagram for using_clause.
The above syntax diagram is explained as follows:
- The execute part of an anonymous block starts with a BEGIN statement, has a break with an END statement, and ends with a semicolon (;).
- USING [IN|OUT|IN OUT]bind_argument: specifies where the variable passed to the stored procedure parameter value is stored. The modifiers in front of bind_argument and of the corresponding parameter are the same.
- The input and output parameters in the middle of an anonymous block are designated by placeholders. The numbers of the placeholders and parameters are the same. The sequences of the parameters corresponding to the placeholders and the USING parameters are the same.

- Parameters can be bound only when SQL statements and stored procedures are called in anonymous blocks. For example, expressions and cursors are used in anonymous blocks, and dynamic statements are called in nested mode in anonymous blocks.
- Output parameters cannot be bound when the SELECT INTO statement in an anonymous block calls FUNCTION/PROCEDURE that contains output parameters.
- Variables declared in an anonymous block and binding parameters cannot be used in the same statement at the same time.
- The PERFORM keyword cannot be used to call a stored procedure when parameters are bound.
- When a stored procedure is called, only bound parameters can be used as input and output parameters. Expressions (for example, 1+:va) cannot be used as input and output parameters. In addition, placeholder names cannot contain quoted digits, characters, or character strings.
- When the bound input parameter type is refcursor, the modification in the stored procedure is isolated from the input parameter.
- When the dynamic_sql_check parameter is enabled and the number of placeholders is the same as the number of parameters, an error is reported if placeholders with the same name are used as anonymous block parameters. In this case, you need to rename the placeholders. For details, see Examples.
Examples
gaussdb=# DROP SCHEMA IF EXISTS hr CASCADE; gaussdb=# CREATE SCHEMA hr; CREATE SCHEMA gaussdb=# SET CURRENT_SCHEMA = hr; SET gaussdb=# CREATE TABLE staffs ( staff_id NUMBER, first_name VARCHAR2, salary NUMBER ); CREATE TABLE gaussdb=# INSERT INTO staffs VALUES (200, 'mike', 5800); INSERT 0 1 gaussdb=# INSERT INTO staffs VALUES (201, 'lily', 3000); INSERT 0 1 gaussdb=# INSERT INTO staffs VALUES (202, 'john', 4400); INSERT 0 1 -- Create overloaded functions. gaussdb=# CREATE OR REPLACE PACKAGE pkg1 IS PROCEDURE plus(var1 in int, var2 int, var3 out int); PROCEDURE plus(var1 in out int); END pkg1; / CREATE PACKAGE gaussdb=# CREATE OR REPLACE PACKAGE BODY pkg1 IS PROCEDURE plus(var1 in int, var2 int, var3 out int) AS BEGIN var3 = var1 + var2 + 1; END; PROCEDURE plus(var1 in out int) AS BEGIN var1 = var1 + 1; END; END pkg1; / CREATE PACKAGE BODY -- Create the stored procedure dynamic_proc. gaussdb=# CREATE OR REPLACE PROCEDURE dynamic_proc AS staff_id NUMBER(6) := 200; first_name VARCHAR2(20); salary NUMBER(8,2); BEGIN -- Execute the anonymous block. EXECUTE IMMEDIATE 'begin select first_name, salary into :first_name, :salary from hr.staffs where staff_id= :dno; end;' USING OUT first_name, OUT salary, IN staff_id; dbe_output.print_line(first_name|| ' ' || salary); END; / CREATE PROCEDURE -- Create a stored procedure to call overloaded functions. gaussdb=# CREATE OR REPLACE PROCEDURE dynamic_proc1 AS v_sql VARCHAR2(200); var1 NUMBER(6) := 1; var2 NUMBER(6) := 2; var3 NUMBER(6); BEGIN v_sql := 'begin pkg1.plus(:1, :2, :3); end;'; EXECUTE IMMEDIATE v_sql USING var1, var2, out var3; dbe_output.print_line('var3: ' || var3); END; / CREATE PROCEDURE -- Call the stored procedure. gaussdb=# CALL dynamic_proc(); mike 5800.00 dynamic_proc -------------- (1 row) gaussdb=# CALL dynamic_proc1(); var3: 4 dynamic_proc1 --------------- (1 row) -- Delete the stored procedure. gaussdb=# DROP PROCEDURE dynamic_proc; DROP PROCEDURE gaussdb=# DROP PROCEDURE dynamic_proc1; DROP PROCEDURE -- Example of an error reported when dynamic_sql_check is enabled gaussdb=# SET behavior_compat_options = 'dynamic_sql_check'; SET gaussdb=# CREATE OR REPLACE PROCEDURE test_proc_exception001(a out integer, b inout integer, c integer) as BEGIN a := 1; begin b := 1/0; end; EXCEPTION WHEN others THEN b := 2; END; / CREATE PROCEDURE gaussdb=# DECLARE a integer := 1; c integer; BEGIN execute immediate 'begin test_proc_exception001(:1,:2,:1); end;' using in out a, out c, a; END; / ERROR: argnum not match in Dynamic SQL, using args num : 3 , actual sql args num : 2 CONTEXT: PL/pgSQL function inline_code_block line 4 at EXECUTE statement -- Change the placeholders with the same name. gaussdb=# DECLARE a integer := 1; c integer; BEGIN execute immediate 'begin test_proc_exception001(:1,:2,:3); end;' using in out a, out c, a; END; / ANONYMOUS BLOCK EXECUTE gaussdb=# DROP PROCEDURE test_proc_exception001; DROP PROCEDURE
Feedback
Was this page helpful?
Provide feedbackThank you very much for your feedback. We will continue working to improve the documentation.See the reply and handling status in My Cloud VOC.
For any further questions, feel free to contact us through the chatbot.
Chatbot