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

Arrays

Use of Array Types

Before the use of arrays, an array type needs to be defined:

Define an array type immediately after the AS keyword in a stored procedure. The definition method is as follows:
TYPE array_type IS VARRAY(size) OF data_type;

Related parameters are as follows:

  • array_type: indicates the name of the array type to be defined.
  • VARRAY: indicates the array type to be defined.
  • size: indicates the maximum number of members in the array type to be defined. The value is a positive integer.
  • data_type: indicates the types of members in the array type to be created.
  • In GaussDB, an array automatically increases. If an access violation occurs, a NULL value will be returned, and no error message will be reported.
  • The scope of an array type defined in a stored procedure takes effect only in this storage process.
  • The size supports only the syntax and does not support the function.
  • data_type can also be the record type defined in a stored procedure (anonymous blocks are not supported) or set type, but cannot be the array or cursor type defined in the stored procedure.
  • When data_type is collection, multi-dimensional arrays are not supported.
  • NOT NULL syntax is not supported.
  • The constructors of the array type can be used only in O-compatible mode.
  • The constructor of the array type cannot be used as the default value of a function or stored procedure parameter.
  • When data_type is set to a type that can define the length and precision, such as varchar and numeric, if a varray array is created in a package and invoked outside the package, the restrictions for the length or precision become invalid.

GaussDB supports access to array elements by using parentheses, and it also supports the extend, count, first, last, prior, exists, trim, next, and delete functions.

  • If a stored procedure contains a DML statement (such as SELECT, UPDATE, INSERT, or DELETE), you are advised to use square brackets to access array elements. Using parentheses will access arrays by default. If no array exists, function expressions will be identified.
  • Exercise caution when using the DELETE statement to delete a single element. Otherwise, the element sequence may be incorrect.
  • When the CLOB size is greater than 1 GB, the table of type, record type, and CLOB cannot be used in the input or output parameter, cursor, or raise info in a stored procedure.

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
-- Perform array operations in the stored procedure.
gaussdb=# CREATE OR REPLACE PROCEDURE array_proc AS
DECLARE 
       TYPE ARRAY_INTEGER IS VARRAY(1024) OF INTEGER;--Define the array type.
       ARRINT ARRAY_INTEGER: = ARRAY_INTEGER();  --Declare the variable of the array type.
BEGIN 
       ARRINT.extend(10);  
       FOR I IN 1..10 LOOP  
               ARRINT(I) := I; 
       END LOOP; 
       DBE_OUTPUT.PRINT_LINE(ARRINT.COUNT);  
       DBE_OUTPUT.PRINT_LINE(ARRINT(1));  
       DBE_OUTPUT.PRINT_LINE(ARRINT(10)); 
       DBE_OUTPUT.PRINT_LINE(ARRINT(ARRINT.FIRST)); 
       DBE_OUTPUT.PRINT_LINE(ARRINT(ARRINT.LAST));
       DBE_OUTPUT.PRINT_LINE(ARRINT(ARRINT.NEXT(ARRINT.FIRST)));
       DBE_OUTPUT.PRINT_LINE(ARRINT(ARRINT.PRIOR(ARRINT.LAST)));
       ARRINT.TRIM();
       
       IF ARRINT.EXISTS(10) THEN
           DBE_OUTPUT.PRINT_LINE('Exist 10th element');
       ELSE
           DBE_OUTPUT.PRINT_LINE('Not exist 10th element');
       END IF;
       DBE_OUTPUT.PRINT_LINE(ARRINT.COUNT);
       DBE_OUTPUT.PRINT_LINE(ARRINT(ARRINT.FIRST)); 
       DBE_OUTPUT.PRINT_LINE(ARRINT(ARRINT.LAST));
       ARRINT.DELETE();
END;  
/

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

-- Delete the stored procedure.
gaussdb=# DROP PROCEDURE array_proc;