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

Cursor Loop

Use of cursors in WHILE and LOOP statements is called a cursor loop. Generally, OPEN, FETCH, and CLOSE statements are called in this kind of loop. The following describes a loop that simplifies a cursor loop without the need for these operations. This mode is applicable to a static cursor loop, without executing four steps about a static cursor.

Syntax

Figure 1 shows the syntax diagram of the FOR AS loop.

Figure 1 FOR_AS_loop::=

Precautions

  • The UPDATE operation for the queried table is not allowed in the loop statement.
  • The variable loop_name is automatically defined and is valid only in this loop. Its type is the same as that in the query result of select_statement. The value of loop_name is the query result of select_statement.
  • The specific type of the loop_name variable is not parsed during compilation. If the specific type needs to be parsed (for example, loop_name is used as the input and output parameters of an overloaded function or stored procedure), a compilation error is reported. To parse the specific type of a variable, set behavior_compat_options to allow_procedure_compile_check.
  • The %FOUND, %NOTFOUND, and %ROWCOUNT attributes access the same internal variable in GaussDB. Transactions and the anonymous block do not support multiple cursor accesses at the same time.
  • You can enable the SMP-related GUC parameter (set the GUC parameter query_dop to a value greater than 1 and plsql_beta_feature to 'enable_plsql_smp') so that the cursor loop can be executed on the SMP.

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
-- If cursors need to be executed cyclically and concurrently, enable the following GUC parameters:
gaussdb=# SET query_dop=4;
SET
gaussdb=# SET sql_beta_feature='enable_plsql_smp';
SET
gaussdb=# BEGIN
FOR ROW_TRANS IN 
        SELECT first_name FROM hr.staffs 
    LOOP 
        DBE_OUTPUT.PRINT_LINE (ROW_TRANS.first_name );
    END LOOP;
END;
/
Tom
ANONYMOUS BLOCK EXECUTE

-- Create a table.
gaussdb=# CREATE TABLE integerTable1( A INTEGER);
CREATE TABLE
gaussdb=# CREATE TABLE integerTable2( B INTEGER);
CREATE TABLE
gaussdb=# INSERT INTO integerTable2 VALUES(2);
INSERT 0 1
-- Multiple cursors share the parameters of cursor attributes.
gaussdb=# DECLARE
   CURSOR C1 IS SELECT A FROM integerTable1;-- Declare the cursor.
   CURSOR C2 IS SELECT B FROM integerTable2;
   PI_A INTEGER;
   PI_B INTEGER;
BEGIN
    OPEN C1;-- Open the cursor.
   OPEN C2;
   FETCH C1 INTO PI_A; ---- The values of C1%FOUND and C2%FOUND are FALSE.
   FETCH C2 INTO PI_B; ---- The values of C1%FOUND and C2%FOUND are TRUE.
   -- Determine the cursor status.
   IF C1%FOUND THEN
       IF C2%FOUND THEN
         DBE_OUTPUT.PRINT_LINE('Dual cursor share parameter.');
      END IF;
   END IF;
    CLOSE C1;-- Close the cursor.
   CLOSE C2;
END;
/
ANONYMOUS BLOCK EXECUTE

-- Delete the temporary table.
gaussdb=# DROP TABLE integerTable1;
DROP TABLE
gaussdb=# DROP TABLE integerTable2;
DROP TABLE