4 8.15.1. Declaration of Array Types
5 8.15.2. Array Value Input
6 8.15.3. Accessing Arrays
7 8.15.4. Modifying Arrays
8 8.15.5. Searching in Arrays
9 8.15.6. Array Input and Output Syntax
11 PostgreSQL allows columns of a table to be defined as variable-length
12 multidimensional arrays. Arrays of any built-in or user-defined base
13 type, enum type, composite type, range type, or domain can be created.
15 8.15.1. Declaration of Array Types #
17 To illustrate the use of array types, we create this table:
18 CREATE TABLE sal_emp (
20 pay_by_quarter integer[],
24 As shown, an array data type is named by appending square brackets ([])
25 to the data type name of the array elements. The above command will
26 create a table named sal_emp with a column of type text (name), a
27 one-dimensional array of type integer (pay_by_quarter), which
28 represents the employee's salary by quarter, and a two-dimensional
29 array of text (schedule), which represents the employee's weekly
32 The syntax for CREATE TABLE allows the exact size of arrays to be
33 specified, for example:
34 CREATE TABLE tictactoe (
38 However, the current implementation ignores any supplied array size
39 limits, i.e., the behavior is the same as for arrays of unspecified
42 The current implementation does not enforce the declared number of
43 dimensions either. Arrays of a particular element type are all
44 considered to be of the same type, regardless of size or number of
45 dimensions. So, declaring the array size or number of dimensions in
46 CREATE TABLE is simply documentation; it does not affect run-time
49 An alternative syntax, which conforms to the SQL standard by using the
50 keyword ARRAY, can be used for one-dimensional arrays. pay_by_quarter
51 could have been defined as:
52 pay_by_quarter integer ARRAY[4],
54 Or, if no array size is to be specified:
55 pay_by_quarter integer ARRAY,
57 As before, however, PostgreSQL does not enforce the size restriction in
60 8.15.2. Array Value Input #
62 To write an array value as a literal constant, enclose the element
63 values within curly braces and separate them by commas. (If you know C,
64 this is not unlike the C syntax for initializing structures.) You can
65 put double quotes around any element value, and must do so if it
66 contains commas or curly braces. (More details appear below.) Thus, the
67 general format of an array constant is the following:
68 '{ val1 delim val2 delim ... }'
70 where delim is the delimiter character for the type, as recorded in its
71 pg_type entry. Among the standard data types provided in the PostgreSQL
72 distribution, all use a comma (,), except for type box which uses a
73 semicolon (;). Each val is either a constant of the array element type,
74 or a subarray. An example of an array constant is:
75 '{{1,2,3},{4,5,6},{7,8,9}}'
77 This constant is a two-dimensional, 3-by-3 array consisting of three
78 subarrays of integers.
80 To set an element of an array constant to NULL, write NULL for the
81 element value. (Any upper- or lower-case variant of NULL will do.) If
82 you want an actual string value “NULL”, you must put double quotes
85 (These kinds of array constants are actually only a special case of the
86 generic type constants discussed in Section 4.1.2.7. The constant is
87 initially treated as a string and passed to the array input conversion
88 routine. An explicit type specification might be necessary.)
90 Now we can show some INSERT statements:
93 '{10000, 10000, 10000, 10000}',
94 '{{"meeting", "lunch"}, {"training", "presentation"}}');
98 '{20000, 25000, 25000, 25000}',
99 '{{"breakfast", "consulting"}, {"meeting", "lunch"}}');
101 The result of the previous two inserts looks like this:
102 SELECT * FROM sal_emp;
103 name | pay_by_quarter | schedule
104 -------+---------------------------+-------------------------------------------
105 Bill | {10000,10000,10000,10000} | {{meeting,lunch},{training,presentation}}
106 Carol | {20000,25000,25000,25000} | {{breakfast,consulting},{meeting,lunch}}
109 Multidimensional arrays must have matching extents for each dimension.
110 A mismatch causes an error, for example:
113 '{10000, 10000, 10000, 10000}',
114 '{{"meeting", "lunch"}, {"meeting"}}');
115 ERROR: malformed array literal: "{{"meeting", "lunch"}, {"meeting"}}"
116 DETAIL: Multidimensional arrays must have sub-arrays with matching dimensions.
118 The ARRAY constructor syntax can also be used:
121 ARRAY[10000, 10000, 10000, 10000],
122 ARRAY[['meeting', 'lunch'], ['training', 'presentation']]);
126 ARRAY[20000, 25000, 25000, 25000],
127 ARRAY[['breakfast', 'consulting'], ['meeting', 'lunch']]);
129 Notice that the array elements are ordinary SQL constants or
130 expressions; for instance, string literals are single quoted, instead
131 of double quoted as they would be in an array literal. The ARRAY
132 constructor syntax is discussed in more detail in Section 4.2.12.
134 8.15.3. Accessing Arrays #
136 Now, we can run some queries on the table. First, we show how to access
137 a single element of an array. This query retrieves the names of the
138 employees whose pay changed in the second quarter:
139 SELECT name FROM sal_emp WHERE pay_by_quarter[1] <> pay_by_quarter[2];
146 The array subscript numbers are written within square brackets. By
147 default PostgreSQL uses a one-based numbering convention for arrays,
148 that is, an array of n elements starts with array[1] and ends with
151 This query retrieves the third quarter pay of all employees:
152 SELECT pay_by_quarter[3] FROM sal_emp;
160 We can also access arbitrary rectangular slices of an array, or
161 subarrays. An array slice is denoted by writing lower-bound:upper-bound
162 for one or more array dimensions. For example, this query retrieves the
163 first item on Bill's schedule for the first two days of the week:
164 SELECT schedule[1:2][1:1] FROM sal_emp WHERE name = 'Bill';
167 ------------------------
168 {{meeting},{training}}
171 If any dimension is written as a slice, i.e., contains a colon, then
172 all dimensions are treated as slices. Any dimension that has only a
173 single number (no colon) is treated as being from 1 to the number
174 specified. For example, [2] is treated as [1:2], as in this example:
175 SELECT schedule[1:2][2] FROM sal_emp WHERE name = 'Bill';
178 -------------------------------------------
179 {{meeting,lunch},{training,presentation}}
182 To avoid confusion with the non-slice case, it's best to use slice
183 syntax for all dimensions, e.g., [1:2][1:1], not [2][1:1].
185 It is possible to omit the lower-bound and/or upper-bound of a slice
186 specifier; the missing bound is replaced by the lower or upper limit of
187 the array's subscripts. For example:
188 SELECT schedule[:2][2:] FROM sal_emp WHERE name = 'Bill';
191 ------------------------
192 {{lunch},{presentation}}
195 SELECT schedule[:][1:1] FROM sal_emp WHERE name = 'Bill';
198 ------------------------
199 {{meeting},{training}}
202 An array subscript expression will return null if either the array
203 itself or any of the subscript expressions are null. Also, null is
204 returned if a subscript is outside the array bounds (this case does not
205 raise an error). For example, if schedule currently has the dimensions
206 [1:3][1:2] then referencing schedule[3][3] yields NULL. Similarly, an
207 array reference with the wrong number of subscripts yields a null
208 rather than an error.
210 An array slice expression likewise yields null if the array itself or
211 any of the subscript expressions are null. However, in other cases such
212 as selecting an array slice that is completely outside the current
213 array bounds, a slice expression yields an empty (zero-dimensional)
214 array instead of null. (This does not match non-slice behavior and is
215 done for historical reasons.) If the requested slice partially overlaps
216 the array bounds, then it is silently reduced to just the overlapping
217 region instead of returning null.
219 The current dimensions of any array value can be retrieved with the
221 SELECT array_dims(schedule) FROM sal_emp WHERE name = 'Carol';
228 array_dims produces a text result, which is convenient for people to
229 read but perhaps inconvenient for programs. Dimensions can also be
230 retrieved with array_upper and array_lower, which return the upper and
231 lower bound of a specified array dimension, respectively:
232 SELECT array_upper(schedule, 1) FROM sal_emp WHERE name = 'Carol';
239 array_length will return the length of a specified array dimension:
240 SELECT array_length(schedule, 1) FROM sal_emp WHERE name = 'Carol';
247 cardinality returns the total number of elements in an array across all
248 dimensions. It is effectively the number of rows a call to unnest would
250 SELECT cardinality(schedule) FROM sal_emp WHERE name = 'Carol';
257 8.15.4. Modifying Arrays #
259 An array value can be replaced completely:
260 UPDATE sal_emp SET pay_by_quarter = '{25000,25000,27000,27000}'
261 WHERE name = 'Carol';
263 or using the ARRAY expression syntax:
264 UPDATE sal_emp SET pay_by_quarter = ARRAY[25000,25000,27000,27000]
265 WHERE name = 'Carol';
267 An array can also be updated at a single element:
268 UPDATE sal_emp SET pay_by_quarter[4] = 15000
271 or updated in a slice:
272 UPDATE sal_emp SET pay_by_quarter[1:2] = '{27000,27000}'
273 WHERE name = 'Carol';
275 The slice syntaxes with omitted lower-bound and/or upper-bound can be
276 used too, but only when updating an array value that is not NULL or
277 zero-dimensional (otherwise, there is no existing subscript limit to
280 A stored array value can be enlarged by assigning to elements not
281 already present. Any positions between those previously present and the
282 newly assigned elements will be filled with nulls. For example, if
283 array myarray currently has 4 elements, it will have six elements after
284 an update that assigns to myarray[6]; myarray[5] will contain null.
285 Currently, enlargement in this fashion is only allowed for
286 one-dimensional arrays, not multidimensional arrays.
288 Subscripted assignment allows creation of arrays that do not use
289 one-based subscripts. For example one might assign to myarray[-2:7] to
290 create an array with subscript values from -2 to 7.
292 New array values can also be constructed using the concatenation
294 SELECT ARRAY[1,2] || ARRAY[3,4];
300 SELECT ARRAY[5,6] || ARRAY[[1,2],[3,4]];
302 ---------------------
306 The concatenation operator allows a single element to be pushed onto
307 the beginning or end of a one-dimensional array. It also accepts two
308 N-dimensional arrays, or an N-dimensional and an N+1-dimensional array.
310 When a single element is pushed onto either the beginning or end of a
311 one-dimensional array, the result is an array with the same lower bound
312 subscript as the array operand. For example:
313 SELECT array_dims(1 || '[0:1]={2,3}'::int[]);
319 SELECT array_dims(ARRAY[1,2] || 3);
325 When two arrays with an equal number of dimensions are concatenated,
326 the result retains the lower bound subscript of the left-hand operand's
327 outer dimension. The result is an array comprising every element of the
328 left-hand operand followed by every element of the right-hand operand.
330 SELECT array_dims(ARRAY[1,2] || ARRAY[3,4,5]);
336 SELECT array_dims(ARRAY[[1,2],[3,4]] || ARRAY[[5,6],[7,8],[9,0]]);
342 When an N-dimensional array is pushed onto the beginning or end of an
343 N+1-dimensional array, the result is analogous to the element-array
344 case above. Each N-dimensional sub-array is essentially an element of
345 the N+1-dimensional array's outer dimension. For example:
346 SELECT array_dims(ARRAY[1,2] || ARRAY[[3,4],[5,6]]);
352 An array can also be constructed by using the functions array_prepend,
353 array_append, or array_cat. The first two only support one-dimensional
354 arrays, but array_cat supports multidimensional arrays. Some examples:
355 SELECT array_prepend(1, ARRAY[2,3]);
361 SELECT array_append(ARRAY[1,2], 3);
367 SELECT array_cat(ARRAY[1,2], ARRAY[3,4]);
373 SELECT array_cat(ARRAY[[1,2],[3,4]], ARRAY[5,6]);
375 ---------------------
379 SELECT array_cat(ARRAY[5,6], ARRAY[[1,2],[3,4]]);
381 ---------------------
384 In simple cases, the concatenation operator discussed above is
385 preferred over direct use of these functions. However, because the
386 concatenation operator is overloaded to serve all three cases, there
387 are situations where use of one of the functions is helpful to avoid
388 ambiguity. For example consider:
389 SELECT ARRAY[1, 2] || '{3, 4}'; -- the untyped literal is taken as an array
394 SELECT ARRAY[1, 2] || '7'; -- so is this one
395 ERROR: malformed array literal: "7"
397 SELECT ARRAY[1, 2] || NULL; -- so is an undecorated NULL
403 SELECT array_append(ARRAY[1, 2], NULL); -- this might have been meant
408 In the examples above, the parser sees an integer array on one side of
409 the concatenation operator, and a constant of undetermined type on the
410 other. The heuristic it uses to resolve the constant's type is to
411 assume it's of the same type as the operator's other input — in this
412 case, integer array. So the concatenation operator is presumed to
413 represent array_cat, not array_append. When that's the wrong choice, it
414 could be fixed by casting the constant to the array's element type; but
415 explicit use of array_append might be a preferable solution.
417 8.15.5. Searching in Arrays #
419 To search for a value in an array, each value must be checked. This can
420 be done manually, if you know the size of the array. For example:
421 SELECT * FROM sal_emp WHERE pay_by_quarter[1] = 10000 OR
422 pay_by_quarter[2] = 10000 OR
423 pay_by_quarter[3] = 10000 OR
424 pay_by_quarter[4] = 10000;
426 However, this quickly becomes tedious for large arrays, and is not
427 helpful if the size of the array is unknown. An alternative method is
428 described in Section 9.25. The above query could be replaced by:
429 SELECT * FROM sal_emp WHERE 10000 = ANY (pay_by_quarter);
431 In addition, you can find rows where the array has all values equal to
433 SELECT * FROM sal_emp WHERE 10000 = ALL (pay_by_quarter);
435 Alternatively, the generate_subscripts function can be used. For
438 (SELECT pay_by_quarter,
439 generate_subscripts(pay_by_quarter, 1) AS s
441 WHERE pay_by_quarter[s] = 10000;
443 This function is described in Table 9.70.
445 You can also search an array using the && operator, which checks
446 whether the left operand overlaps with the right operand. For instance:
447 SELECT * FROM sal_emp WHERE pay_by_quarter && ARRAY[10000];
449 This and other array operators are further described in Section 9.19.
450 It can be accelerated by an appropriate index, as described in
453 You can also search for specific values in an array using the
454 array_position and array_positions functions. The former returns the
455 subscript of the first occurrence of a value in an array; the latter
456 returns an array with the subscripts of all occurrences of the value in
457 the array. For example:
458 SELECT array_position(ARRAY['sun','mon','tue','wed','thu','fri','sat'], 'mon');
464 SELECT array_positions(ARRAY[1, 4, 3, 1, 3, 4, 2, 1], 1);
472 Arrays are not sets; searching for specific array elements can be a
473 sign of database misdesign. Consider using a separate table with a row
474 for each item that would be an array element. This will be easier to
475 search, and is likely to scale better for a large number of elements.
477 8.15.6. Array Input and Output Syntax #
479 The external text representation of an array value consists of items
480 that are interpreted according to the I/O conversion rules for the
481 array's element type, plus decoration that indicates the array
482 structure. The decoration consists of curly braces ({ and }) around the
483 array value plus delimiter characters between adjacent items. The
484 delimiter character is usually a comma (,) but can be something else:
485 it is determined by the typdelim setting for the array's element type.
486 Among the standard data types provided in the PostgreSQL distribution,
487 all use a comma, except for type box, which uses a semicolon (;). In a
488 multidimensional array, each dimension (row, plane, cube, etc.) gets
489 its own level of curly braces, and delimiters must be written between
490 adjacent curly-braced entities of the same level.
492 The array output routine will put double quotes around element values
493 if they are empty strings, contain curly braces, delimiter characters,
494 double quotes, backslashes, or white space, or match the word NULL.
495 Double quotes and backslashes embedded in element values will be
496 backslash-escaped. For numeric data types it is safe to assume that
497 double quotes will never appear, but for textual data types one should
498 be prepared to cope with either the presence or absence of quotes.
500 By default, the lower bound index value of an array's dimensions is set
501 to one. To represent arrays with other lower bounds, the array
502 subscript ranges can be specified explicitly before writing the array
503 contents. This decoration consists of square brackets ([]) around each
504 array dimension's lower and upper bounds, with a colon (:) delimiter
505 character in between. The array dimension decoration is followed by an
506 equal sign (=). For example:
507 SELECT f1[1][-2][3] AS e1, f1[1][-1][5] AS e2
508 FROM (SELECT '[1:1][-2:-1][3:5]={{{1,2,3},{4,5,6}}}'::int[] AS f1) AS ss;
515 The array output routine will include explicit dimensions in its result
516 only when there are one or more lower bounds different from one.
518 If the value written for an element is NULL (in any case variant), the
519 element is taken to be NULL. The presence of any quotes or backslashes
520 disables this and allows the literal string value “NULL” to be entered.
521 Also, for backward compatibility with pre-8.2 versions of PostgreSQL,
522 the array_nulls configuration parameter can be turned off to suppress
523 recognition of NULL as a NULL.
525 As shown previously, when writing an array value you can use double
526 quotes around any individual array element. You must do so if the
527 element value would otherwise confuse the array-value parser. For
528 example, elements containing curly braces, commas (or the data type's
529 delimiter character), double quotes, backslashes, or leading or
530 trailing whitespace must be double-quoted. Empty strings and strings
531 matching the word NULL must be quoted, too. To put a double quote or
532 backslash in a quoted array element value, precede it with a backslash.
533 Alternatively, you can avoid quotes and use backslash-escaping to
534 protect all data characters that would otherwise be taken as array
537 You can add whitespace before a left brace or after a right brace. You
538 can also add whitespace before or after any individual item string. In
539 all of these cases the whitespace will be ignored. However, whitespace
540 within double-quoted elements, or surrounded on both sides by
541 non-whitespace characters of an element, is not ignored.
545 The ARRAY constructor syntax (see Section 4.2.12) is often easier to
546 work with than the array-literal syntax when writing array values in
547 SQL commands. In ARRAY, individual element values are written the same
548 way they would be written when not members of an array.