Updated on 2024-06-03 GMT+08:00

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 for dynamically calling an anonymous block.

Figure 1 call_anonymous_block::=

Figure 2 shows the syntax diagram for using_clause.

Figure 2 using_clause::=

The syntax is described as follows:

  • The execution section 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 the variable whose value is passed to the stored procedure parameter. 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.
  • The IMMEDIATE keyword is used only for syntax compatibility and has no actual meaning.
  • When the bound input parameter type is refcursor, the modification in the stored procedure is isolated from the input parameter.

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

-- Call the stored procedure.
gaussdb=# CALL dynamic_proc();
mike 5800.00
 dynamic_proc 
--------------

(1 row)
-- Delete the stored procedure.
gaussdb=# DROP PROCEDURE dynamic_proc;
DROP PROCEDURE