
particularly in the CREATE TYPE reference page. Fix some other errors in the CREATE TYPE page, too.
240 lines
6.9 KiB
Plaintext
240 lines
6.9 KiB
Plaintext
<!-- $Header: /cvsroot/pgsql/doc/src/sgml/array.sgml,v 1.13 2001/11/03 21:42:47 tgl Exp $ -->
|
|
|
|
<chapter id="arrays">
|
|
<title>Arrays</title>
|
|
|
|
<indexterm>
|
|
<primary>arrays</primary>
|
|
</indexterm>
|
|
|
|
<para>
|
|
<productname>Postgres</productname> allows columns of a table to be
|
|
defined as variable-length multidimensional arrays. Arrays of any
|
|
built-in type or user-defined type can be created. To illustrate
|
|
their use, we create this table:
|
|
<programlisting>
|
|
CREATE TABLE sal_emp (
|
|
name text,
|
|
pay_by_quarter integer[],
|
|
schedule text[][]
|
|
);
|
|
</programlisting>
|
|
The above query will create a table named
|
|
<structname>sal_emp</structname> with a <type>text</type> string
|
|
(<structfield>name</structfield>), a one-dimensional array of type
|
|
<type>integer</type> (<structfield>pay_by_quarter</structfield>),
|
|
which represents the employee's salary by quarter, and a
|
|
two-dimensional array of <type>text</type>
|
|
(<structfield>schedule</structfield>), which represents the
|
|
employee's weekly schedule.
|
|
</para>
|
|
|
|
<para>
|
|
Now we do some <command>INSERT</command>s. Observe that to write an array
|
|
value, we enclose the element values within braces and separate them
|
|
by commas. If you know C, this is not unlike the syntax for
|
|
initializing structures.
|
|
|
|
<programlisting>
|
|
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"}}');
|
|
</programlisting>
|
|
</para>
|
|
|
|
<para>
|
|
Now, we can run some queries on <structname>sal_emp</structname>.
|
|
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:
|
|
|
|
<programlisting>
|
|
SELECT name FROM sal_emp WHERE pay_by_quarter[1] <> pay_by_quarter[2];
|
|
|
|
name
|
|
-------
|
|
Carol
|
|
(1 row)
|
|
</programlisting>
|
|
|
|
<productname>Postgres</productname> uses the
|
|
<quote>one-based</quote> numbering convention for arrays, that is,
|
|
an array of n elements starts with <literal>array[1]</literal> and
|
|
ends with <literal>array[n]</literal>.
|
|
</para>
|
|
|
|
<para>
|
|
This query retrieves the third quarter pay of all employees:
|
|
|
|
<programlisting>
|
|
SELECT pay_by_quarter[3] FROM sal_emp;
|
|
|
|
pay_by_quarter
|
|
----------------
|
|
10000
|
|
25000
|
|
(2 rows)
|
|
</programlisting>
|
|
</para>
|
|
|
|
<para>
|
|
We can also access arbitrary rectangular slices of an array, or
|
|
subarrays. An array slice is denoted by writing
|
|
<literal><replaceable>lower subscript</replaceable> :
|
|
<replaceable>upper subscript</replaceable></literal> for one or more
|
|
array dimensions. This query retrieves the first item on Bill's
|
|
schedule for the first two days of the week:
|
|
|
|
<programlisting>
|
|
SELECT schedule[1:2][1:1] FROM sal_emp WHERE name = 'Bill';
|
|
|
|
schedule
|
|
--------------------
|
|
{{"meeting"},{""}}
|
|
(1 row)
|
|
</programlisting>
|
|
|
|
We could also have written
|
|
|
|
<programlisting>
|
|
SELECT schedule[1:2][1] FROM sal_emp WHERE name = 'Bill';
|
|
</programlisting>
|
|
|
|
with the same result. An array subscripting operation is taken to
|
|
represent an array slice if any of the subscripts are written in the
|
|
form <replaceable>lower</replaceable> <literal>:</literal>
|
|
<replaceable>upper</replaceable>. A lower bound of 1 is assumed for
|
|
any subscript where only one value is specified.
|
|
</para>
|
|
|
|
<para>
|
|
An array value can be replaced completely:
|
|
|
|
<programlisting>
|
|
UPDATE sal_emp SET pay_by_quarter = '{25000,25000,27000,27000}'
|
|
WHERE name = 'Carol';
|
|
</programlisting>
|
|
|
|
or updated at a single element:
|
|
|
|
<programlisting>
|
|
UPDATE sal_emp SET pay_by_quarter[4] = 15000
|
|
WHERE name = 'Bill';
|
|
</programListing>
|
|
|
|
or updated in a slice:
|
|
|
|
<programlisting>
|
|
UPDATE sal_emp SET pay_by_quarter[1:2] = '{27000,27000}'
|
|
WHERE name = 'Carol';
|
|
</programlisting>
|
|
</para>
|
|
|
|
<para>
|
|
An array can be enlarged by assigning to an element adjacent to
|
|
those already present, or by assigning to a slice that is adjacent
|
|
to or overlaps the data already present. For example, if an array
|
|
value currently has 4 elements, it will have five elements after an
|
|
update that assigns to array[5]. Currently, enlargement in this
|
|
fashion is only allowed for one-dimensional arrays, not
|
|
multidimensional arrays.
|
|
</para>
|
|
|
|
<para>
|
|
The syntax for <command>CREATE TABLE</command> allows fixed-length
|
|
arrays to be defined:
|
|
|
|
<programlisting>
|
|
CREATE TABLE tictactoe (
|
|
squares integer[3][3]
|
|
);
|
|
</programlisting>
|
|
|
|
However, the current implementation does not enforce the array size
|
|
limits --- the behavior is the same as for arrays of unspecified
|
|
length.
|
|
</para>
|
|
|
|
<para>
|
|
Actually, the current implementation does not enforce the declared
|
|
number of dimensions either. Arrays of a particular base type are
|
|
all considered to be of the same type, regardless of size or number
|
|
of dimensions.
|
|
</para>
|
|
|
|
<para>
|
|
The current dimensions of any array value can be retrieved with the
|
|
<function>array_dims</function> function:
|
|
|
|
<programlisting>
|
|
SELECT array_dims(schedule) FROM sal_emp WHERE name = 'Carol';
|
|
|
|
array_dims
|
|
------------
|
|
[1:2][1:1]
|
|
(1 row)
|
|
</programlisting>
|
|
|
|
<function>array_dims</function> produces a <type>text</type> result,
|
|
which is convenient for people to read but perhaps not so convenient
|
|
for programs.
|
|
</para>
|
|
|
|
<para>
|
|
To search for a value in an array, you must check each value of the
|
|
array. This can be done by hand (if you know the size of the array):
|
|
|
|
<programlisting>
|
|
SELECT * FROM sal_emp WHERE pay_by_quarter[1] = 10000 OR
|
|
pay_by_quarter[2] = 10000 OR
|
|
pay_by_quarter[3] = 10000 OR
|
|
pay_by_quarter[4] = 10000;
|
|
</programlisting>
|
|
|
|
However, this quickly becomes tedious for large arrays, and is not
|
|
helpful if the size of the array is unknown. Although it is not part
|
|
of the primary <productname>PostgreSQL</productname> distribution,
|
|
there is an extension available that defines new functions and
|
|
operators for iterating over array values. Using this, the above
|
|
query could be:
|
|
|
|
<programlisting>
|
|
SELECT * FROM sal_emp WHERE pay_by_quarter[1:4] *= 10000;
|
|
</programlisting>
|
|
|
|
To search the entire array (not just specified columns), you could
|
|
use:
|
|
|
|
<programlisting>
|
|
SELECT * FROM sal_emp WHERE pay_by_quarter *= 10000;
|
|
</programlisting>
|
|
|
|
In addition, you could find rows where the array had all values
|
|
equal to 10 000 with:
|
|
|
|
<programlisting>
|
|
SELECT * FROM sal_emp WHERE pay_by_quarter **= 10000;
|
|
</programlisting>
|
|
|
|
To install this optional module, look in the
|
|
<filename>contrib/array</filename> directory of the
|
|
<productname>PostgreSQL</productname> source distribution.
|
|
</para>
|
|
|
|
<tip>
|
|
<para>
|
|
Arrays are not lists; using arrays in the manner described in the
|
|
previous paragraph is often a sign of database misdesign. The
|
|
array field should generally be split off into a separate table.
|
|
Tables can obviously be searched easily.
|
|
</para>
|
|
</tip>
|
|
|
|
</chapter>
|