Chapter 8. Arrays

Note: This must become a chapter on array behavior. Volunteers? - thomas 1998-01-12

Postgres allows attributes of a class to be defined as variable-length multi-dimensional arrays. Arrays of any built-in type or user-defined type can be created. To illustrate their use, we create this class:

CREATE TABLE sal_emp (
    name            text,
    pay_by_quarter  int4[],
    schedule        text[][]
);

The above query will create a class named sal_emp with a text string (name), a one-dimensional array of int4 (pay_by_quarter), which represents the employee's salary by quarter, and a two-dimensional array of text (schedule), which represents the employee's weekly schedule. Now we do some INSERTSs; note that when appending to an array, we enclose the values within braces and separate them by commas. If you know C, this is not unlike the syntax for initializing structures.

INSERT INTO sal_emp
    VALUES ('Bill',
    '{10000, 10000, 10000, 10000}',
    '{{"meeting", "lunch"}, {}}');

INSERT INTO sal_emp
    VALUES ('Carol',
    '{20000, 25000, 25000, 25000}',
    '{{"talk", "consult"}, {"meeting"}}');
Now, we can run some queries on sal_emp. First, we show how to access a single element of an array at a time. This query retrieves the names of the employees whose pay changed in the second quarter:
SELECT name FROM sal_emp WHERE pay_by_quarter[1] <> pay_by_quarter[2];

 name
-------
 Carol
(1 row)
Postgres uses the "one-based" numbering convention for arrays --- that is, an array of n elements starts with array[1] and ends with array[n].

This query retrieves the third quarter pay of all employees:

SELECT pay_by_quarter[3] FROM sal_emp;

 pay_by_quarter
----------------
          10000
          25000
(2 rows)

We can also access arbitrary slices of an array, or subarrays. An array slice is denoted by writing "lower subscript : upper subscript" for one or more array dimensions. This query retrieves the first item on Bill's schedule for the first two days of the week:

SELECT schedule[1:2][1:1] FROM sal_emp WHERE name = 'Bill';

      schedule
--------------------
 {{"meeting"},{""}}
(1 row)
We could also have written
SELECT schedule[1:2][1] FROM sal_emp WHERE name = 'Bill';
with the same result.

An array value can be replaced completely:

UPDATE sal_emp SET pay_by_quarter = '{25000,25000,27000,27000}'
    WHERE name = 'Carol';
or updated at a single entry:
UPDATE sal_emp SET pay_by_quarter[4] = 15000
    WHERE name = 'Bill';
or updated in a slice:
UPDATE sal_emp SET pay_by_quarter[1:2] = '{27000,27000}'
    WHERE name = 'Carol';

It is not currently possible to resize an array value except by complete replacement; for example, we couldn't change a four- element array value to a five-element value with a single assignment to array[5].

The syntax for CREATE TABLE allows fixed-length arrays to be defined:

CREATE TABLE tictactoe (
    squares   int4[3][3]
);
However, the current implementation does not enforce the array size limits --- the behavior is the same as for arrays of unspecified length.