Updated on 2024-08-20 GMT+08:00

Array Types

Array types can be used to store several elements of the same type.

Array Type Definition

Generally, an array data type is named by adding square brackets ([]) to the end of the data type name of an array element.

Example 1: Create a table named sal_emp. The table has the following columns: name of the text type, indicating employee names; pay_by_quarter of the integer element type, indicating an array of quarterly salaries; phone_numbers of the varchar(11) element type, indicating an array of mobile numbers.

gaussdb=# CREATE TABLE sal_emp (
name            text,
 pay_by_quarter  integer[],
phone_numbers   varchar(11)[]
gaussdb=# );
gaussdb=# DROP TABLE sal_emp;

Example 2: Define an array type in other ways. For details about the definition method and behavior, see the comments in the example.

gaussdb=# CREATE TABLE sal_emp (
name             text,
 pay_by_quarter1  integer[][],      -- Two-dimensional array of the int type.
 pay_by_quarter2  integer[3],       -- One-dimensional array of the int type. The size is 3.
 pay_by_quarter3  integer[3][3],    -- Two-dimensional array of the int type. The size of each dimension is 3.
 pay_by_quarter4  integer ARRAY,    -- One-dimensional array of the int type.
 pay_by_quarter5  integer ARRAY[3]  -- One-dimensional array of the int type. The size is 3.
);
gaussdb=# DROP TABLE sal_emp;
  • The definition of the number of dimensions of an array does not take effect (which does not affect the runtime behavior). You are advised to use the method described in example 1 to define the array type and do not use multidimensional array data.
  • The definition of the array size does not take effect (which does not affect the runtime behavior). You are advised to use the method described in example 1 to define the array type.
  • The maximum number of dimensions of an array is 6.
  • The restrictions on the number of array elements are as follows:
    1. The maximum number of elements is 134217727.
    2. The maximum storage space of all elements cannot exceed 1 GB minus 1 byte, that is, 1073741823 bytes.

Array Constructor

An array constructor is an expression that can build array values. A simple array constructor consists of the keyword ARRAY and an expression list of array element values which are separated by commas and enclosed (,) by square brackets ([]). For example:

gaussdb=# SELECT ARRAY[1, 2, 3 + 4];
  array  
---------
 {1,2,7}
(1 row)

By default, the element type of an array is the common type of member expressions and is determined by the same rules as the UNION or CASE structure (UNION, CASE, and Related Constructs). You can construct an array to the desired data type through explicit type conversion. The following is an example:

gaussdb=# SELECT ARRAY[1, 2, 3]::varchar[];
  array  
---------
 {1,2,3}
(1 row)

gaussdb=# SELECT ARRAY['a', 'b', 'c'];
  array  
---------
 {a,b,c}
(1 row)

gaussdb=# SELECT ARRAY['a', 'b', 'c']::int[];
ERROR:  invalid input syntax for integer: "a"
LINE 1: select ARRAY['a', 'b', 'c']::int[];
                     ^
CONTEXT:  referenced column: array

gaussdb=# SELECT ARRAY[1::int, 'b', 'c'];
ERROR:  invalid input syntax for integer: "b"
LINE 1: select ARRAY[1::int, 'b', 'c'];
                             ^
CONTEXT:  referenced column: array

In addition to the preset basic types, the record type and table type can also be defined as array types. The following is an example:

gaussdb=# CREATE TYPE rec IS (c1 int, c2 int);
gaussdb=# SELECT ARRAY[(1, 1), (2, 2)]::rec[];
       array       
-------------------
 {"(1,1)","(2,2)"}
(1 row)

gaussdb=# SELECT ARRAY[rec(1, 1), rec(2, 2)];
       array       
-------------------
 {"(1,1)","(2,2)"}
(1 row)

gaussdb=# CREATE TABLE tab (c1 int, c2 int);
gaussdb=# SELECT ARRAY[(1, 1), (2, 2)]::tab[];
       array       
-------------------
 {"(1,1)","(2,2)"}
(1 row)

gaussdb=# DROP TYPE rec;
gaussdb=# DROP TABLE tab;

An array must have a type. Therefore, when constructing an empty array, you must construct it as the required type. For example:

gaussdb=# SELECT ARRAY[]::int[];
 array 
-------
 {}
(1 row)

You can also construct an array from the result of a subquery. In this case, the array constructor consists of the keyword ARRAY and a subquery enclosed in parentheses. The subquery must return only one separate column. The generated one-dimensional array generates an element for each row of the result in the subquery. The element type matches the output column of the subquery. For example:

gaussdb=# SELECT ARRAY(select generate_series(1, 6));
     array     
---------------
 {1,2,3,4,5,6}
(1 row)

Multidimensional array values can be made by nesting array constructors. The ARRAY keyword in the inner constructor can be omitted. For example, the following two examples show the same result:

gaussdb=# SELECT ARRAY[ARRAY[1,2], ARRAY[3,4]];
     array     
---------------
 {{1,2},{3,4}}
(1 row)

gaussdb=# SELECT ARRAY[[1,2], [3,4]];
     array     
---------------
 {{1,2},{3,4}}
(1 row)
  • Inner constructors at the same layer must generate subarrays of the same dimension.
  • Any type conversion applied to the outer ARRAY constructor is automatically applied to all inner constructors.

String Inputs of the Array Type

To write an array value as a literal constant (constant input), enclose the element values with braces and separate them with commas. The general format of an array constant is as follows:

'{ val1 delim val2 delim ... }'

In the preceding format, delim indicates the delimiter of the element type and is recorded in the typdelim column in the pg_type catalog of the type. Each val can be a constant of the array element type or a subarray. For example:

gaussdb=# SELECT '{1, 2, 3}'::int[] AS RESULT;
 result  
---------
 {1,2,3}
(1 row)

gaussdb=# SELECT '{{1, 2, 3}, {4, 5, 6}, {7, 8, 9}}'::int[] AS RESULT;
          result           
---------------------------
 {{1,2,3},{4,5,6},{7,8,9}}
(1 row)

Double quotation marks can be used around any element value, and double quotation marks must be used when the element value contains special characters such as commas or braces. The following is an example:

gaussdb=# SELECT '{" ", "NULL", null, "\\", "{", "}", ","}'::varchar[] AS RESULT;
               result               
------------------------------------
 {" ","NULL",NULL,"\\","{","}",","}
(1 row)

-- This example indicates that there is an array of the varchar type and there are seven varchar elements in total. The elements are as follows:
 1. A character string containing a space. 2. A character string containing "NULL". 3. A character string containing NULL. 4. A character string containing a backslash (\).
 5. A character string containing a left brace ({). 6. A character string containing a right brace (}). 7. A character string containing a comma (,).
  • For array string constant inputs, if the array element value is an empty string, contains braces, delimiters, double quotation marks, backslashes, or spaces, or matches the keyword NULL, then element inputs are enclosed in double quotation marks. An additional backslash is input if the element value contains double quotation marks or backslashes.
  • The keyword NULL is case-insensitive.
  • The input spaces not enclosed in double quotation marks are automatically skipped.
  • You are advised to use the array constructor instead of character constants to construct array data.

String Outputs of the Array Type

The output of an array value consists of the output of the array element type plus some modifiers indicating the array structure. These modifiers consist of braces ({}) around array values plus delimiters between adjacent items. In a multidimensional array, each dimension has its own level of braces and contains delimiters between adjacent braces at the same level.

The data of the array type contains special characters (in the following description). The following is an example of character string output:

gaussdb=# SELECT ARRAY['{', '}', 'hello, world', '"', '\', '  ', NULL] AS RESULT;
                    array                     
----------------------------------------------
 {"{","}","hello, world","\"","\\","  ",NULL}
(1 row)

For array string constant outputs, if the array element value is an empty string, contains braces, delimiters, double quotation marks, backslashes, or spaces, or the element is NULL, then element outputs are enclosed in double quotation marks. An additional backslash is output if the element value contains double quotation marks or backslashes. This parameter corresponds to the string constant inputs.

Use of Array Types

The following is an example of using the array type:

-- Create a table with array columns and insert some data.
gaussdb=# CREATE TABLE orders (
 name  varchar,
items varchar[]
);
gaussdb=# INSERT INTO orders VALUES('a', ARRAY['Apple', 'Orange', 'Pear']);
gaussdb=# INSERT INTO orders VALUES('b', ARRAY['Mineral water', 'Coke', 'Sprite']);
gaussdb=# INSERT INTO orders VALUES('c', ARRAY['Mouse', 'Keyboard', 'Earphone']);
gaussdb=# INSERT INTO orders VALUES('d', '{Cabbage, Potato, Eggplant}');

-- Query data.
gaussdb=# SELECT * FROM orders ORDER BY name;
 name |       items        
------+--------------------
 a    | {Apple,Orange,Pear}
 b    | {Mineral water,Coke,Sprite}
 c    | {Mouse,Keyboard,Earphone}
 d    | {Cabbage,Potato,Eggplant}
(4 rows)

-- Access array elements.
gaussdb=# SELECT items[1] FROM orders ORDER BY name;
 items  
--------
 Apple
 Mineral water
 Mouse
 Cabbage
(4 rows)

-- If the accessed element exceeds the range or the accessed index is NULL, NULL is returned.
gaussdb=# SELECT items[4] FROM orders ORDER BY name;
 items 
-------




(4 rows)

gaussdb=# SELECT items[null] FROM orders ORDER BY name;
 items 
-------




(4 rows)

-- Access a subarray.
gaussdb=# SELECT items[1:2] FROM orders ORDER BY name;
     items     
---------------
 {Apple,Orange}
 {Mineral water,Coke}
 {Mouse,Keyboard}
 {Cabbage,Potato}
(4 rows)

-- Updates the entire array.
gaussdb=# UPDATE orders SET items = ARRAY['Banana', 'Watermelon', 'Strawberry'] WHERE name = 'a';
gaussdb=# SELECT items FROM orders WHERE name = 'a';
      items       
------------------
 {Banana,Watermelon,Strawberry}
(1 row)

-- Updates the elements of an array.
gaussdb=# UPDATE orders SET items[1] = 'Mango' WHERE name = 'a';
gaussdb=# SELECT items FROM orders WHERE name = 'a';
      items       
------------------
 {Mango,Watermelon,Strawberry}
(1 row)

-- Updates the element fragment of an array.
gaussdb=# UPDATE orders SET items[1:2] = ARRAY['Computer','Mobile phone'] WHERE name = 'c';
gaussdb=# SELECT items FROM orders WHERE name = 'c';
      items       
------------------
 {Computer,Mobile phone,Earphone}
(1 row)

-- Add an array element. All unassigned elements between the last element of the original array and the new element are set to NULL.
gaussdb=# UPDATE orders SET items[4] = 'Display' WHERE name = 'c';
gaussdb=# SELECT items FROM orders WHERE name = 'c';
          items          
-------------------------
 {Computer,Mobile phone,Earphone,Display}
(1 row)

gaussdb=# UPDATE orders SET items[6] = 'Display 2' WHERE name = 'c';
gaussdb=# SELECT items FROM orders WHERE name = 'c';
                items                 
--------------------------------------
 {Computer,Mobile phone,Earphone,Display,NULL,Display 2}
(1 row)