array.sgml 19.3 KB
Newer Older
Peter Eisentraut's avatar
Peter Eisentraut committed
1
<!-- $Header: /cvsroot/pgsql/doc/src/sgml/array.sgml,v 1.33 2003/11/04 09:55:38 petere Exp $ -->
2

3
<sect1 id="arrays">
4 5
 <title>Arrays</title>

6
 <indexterm>
Peter Eisentraut's avatar
Peter Eisentraut committed
7
  <primary>array</primary>
8 9
 </indexterm>

10
 <para>
11
  <productname>PostgreSQL</productname> allows columns of a table to be
12
  defined as variable-length multidimensional arrays. Arrays of any
13 14 15 16 17 18 19 20
  built-in type or user-defined type can be created.
 </para>

 <sect2>
  <title>Declaration of Array Types</title>

 <para>
  To illustrate the use of array types, we create this table:
21
<programlisting>
22
CREATE TABLE sal_emp (
23
    name            text,
24
    pay_by_quarter  integer[],
25
    schedule        text[][]
26
);
27
</programlisting>
28
  As shown, an array data type is named by appending square brackets
29 30 31 32 33 34 35 36 37
  (<literal>[]</>) to the data type name of the array elements.  The
  above command will create a table named
  <structname>sal_emp</structname> with a column of type
  <type>text</type> (<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.
38
 </para>
39 40 41 42 43 44 45 46 47 48 49 50 51 52 53 54 55 56 57 58 59 60 61 62 63 64 65 66 67 68 69 70 71 72 73

 <para>
  The syntax for <command>CREATE TABLE</command> allows the exact size of
  arrays to be specified, for example:

<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 element type are
  all considered to be of the same type, regardless of size or number
  of dimensions.  So, declaring number of dimensions or sizes in
  <command>CREATE TABLE</command> is simply documentation, it does not
  affect runtime behavior.
 </para>

 <para>
  An alternative, SQL99-standard syntax may be used for one-dimensional arrays.
  <structfield>pay_by_quarter</structfield> could have been defined as:
<programlisting>
    pay_by_quarter  integer ARRAY[4],
</programlisting>
  This syntax requires an integer constant to denote the array size.
  As before, however, <productname>PostgreSQL</> does not enforce the
  size restriction.
 </para>
74 75 76 77
 </sect2>

 <sect2>
  <title>Array Value Input</title>
78

Peter Eisentraut's avatar
Peter Eisentraut committed
79 80 81 82 83 84 85 86 87 88 89 90 91 92 93 94 95 96 97 98 99 100 101 102 103 104 105 106 107 108 109 110 111 112 113 114 115 116 117
  <indexterm>
   <primary>array</primary>
   <secondary>constant</secondary>
  </indexterm>

  <para>
   To write an array value as a literal constant, enclose the element
   values within curly braces and separate them by commas.  (If you
   know C, this is not unlike the C syntax for initializing
   structures.)  You may put double quotes around any element value,
   and must do so if it contains commas or curly braces.  (More
   details appear below.)  Thus, the general format of an array
   constant is the following:
<synopsis>
'{ <replaceable>val1</replaceable> <replaceable>delim</replaceable> <replaceable>val2</replaceable> <replaceable>delim</replaceable> ... }'
</synopsis>
   where <replaceable>delim</replaceable> is the delimiter character
   for the type, as recorded in its <literal>pg_type</literal> entry.
   (For all built-in types, this is the comma character
   <quote><literal>,</literal></>.)  Each
   <replaceable>val</replaceable> is either a constant of the array
   element type, or a subarray.  An example of an array constant is
<programlisting>
'{{1,2,3},{4,5,6},{7,8,9}}'
</programlisting>
   This constant is a two-dimensional, 3-by-3 array consisting of
   three subarrays of integers.
  </para>

  <para>
   (These kinds of array constants are actually only a special case of
   the generic type constants discussed in <xref
   linkend="sql-syntax-constants-generic">.  The constant is initially
   treated as a string and passed to the array input conversion
   routine.  An explicit type specification might be necessary.)
  </para>

  <para>
   Now we can show some <command>INSERT</command> statements.
118

119
<programlisting>
120
INSERT INTO sal_emp
121 122 123 124
    VALUES ('Bill',
    '{10000, 10000, 10000, 10000}',
    '{{"meeting", "lunch"}, {}}');

125
INSERT INTO sal_emp
126 127 128
    VALUES ('Carol',
    '{20000, 25000, 25000, 25000}',
    '{{"talk", "consult"}, {"meeting"}}');
129
</programlisting>
Peter Eisentraut's avatar
Peter Eisentraut committed
130 131 132 133 134 135 136 137
  </para>

  <para>
   A limitation of the present array implementation is that individual
   elements of an array cannot be SQL null values.  The entire array
   can be set to null, but you can't have an array with some elements
   null and some not.
  </para>
138

139 140 141 142 143 144 145 146 147 148 149 150 151 152 153 154 155
 <para>
  This can lead to surprising results. For example, the result of the
  previous two inserts looks like this:
<programlisting>
SELECT * FROM sal_emp;
 name  |      pay_by_quarter       |      schedule
-------+---------------------------+--------------------
 Bill  | {10000,10000,10000,10000} | {{meeting},{""}}
 Carol | {20000,25000,25000,25000} | {{talk},{meeting}}
(2 rows)
</programlisting>
  Because the <literal>[2][2]</literal> element of
  <structfield>schedule</structfield> is missing in each of the
  <command>INSERT</command> statements, the <literal>[1][2]</literal>
  element is discarded.
 </para>

156 157
 <note>
  <para>
158
   Fixing this is on the to-do list.
159 160
  </para>
 </note>
161 162

 <para>
163
  The <literal>ARRAY</literal> expression syntax may also be used:
164 165 166 167 168 169 170 171 172 173 174 175 176 177 178 179 180 181
<programlisting>
INSERT INTO sal_emp
    VALUES ('Bill',
    ARRAY[10000, 10000, 10000, 10000],
    ARRAY[['meeting', 'lunch'], ['','']]);

INSERT INTO sal_emp
    VALUES ('Carol',
    ARRAY[20000, 25000, 25000, 25000],
    ARRAY[['talk', 'consult'], ['meeting', '']]);
SELECT * FROM sal_emp;
 name  |      pay_by_quarter       |           schedule
-------+---------------------------+-------------------------------
 Bill  | {10000,10000,10000,10000} | {{meeting,lunch},{"",""}}
 Carol | {20000,25000,25000,25000} | {{talk,consult},{meeting,""}}
(2 rows)
</programlisting>
  Note that with this syntax, multidimensional arrays must have matching
182 183 184
  extents for each dimension. A mismatch causes an error report, rather than
  silently discarding values as in the previous case.
  For example:
185 186 187 188 189
<programlisting>
INSERT INTO sal_emp
    VALUES ('Carol',
    ARRAY[20000, 25000, 25000, 25000],
    ARRAY[['talk', 'consult'], ['meeting']]);
190
ERROR:  multidimensional arrays must have array expressions with matching dimensions
191
</programlisting>
192 193 194 195 196
  Also notice that the array elements are ordinary SQL constants or
  expressions; for instance, string literals are single quoted, instead of
  double quoted as they would be in an array literal.  The <literal>ARRAY</>
  expression syntax is discussed in more detail in <xref
  linkend="sql-syntax-array-constructors">.
197
 </para>
198 199 200
 </sect2>

 <sect2>
201
  <title>Accessing Arrays</title>
202

203
 <para>
204
  Now, we can run some queries on the table.
205 206 207
  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:
208
     
209
<programlisting>
210
SELECT name FROM sal_emp WHERE pay_by_quarter[1] &lt;&gt; pay_by_quarter[2];
211

212 213 214 215
 name
-------
 Carol
(1 row)
216
</programlisting>
217

218
  The array subscript numbers are written within square brackets.
219
  By default <productname>PostgreSQL</productname> uses the
220
  one-based numbering convention for arrays, that is,
Peter Eisentraut's avatar
Peter Eisentraut committed
221 222
  an array of <replaceable>n</> elements starts with <literal>array[1]</literal> and
  ends with <literal>array[<replaceable>n</>]</literal>.
223
 </para>
224

225 226
 <para>
  This query retrieves the third quarter pay of all employees:
227
     
228
<programlisting>
229
SELECT pay_by_quarter[3] FROM sal_emp;
230

231 232 233 234 235
 pay_by_quarter
----------------
          10000
          25000
(2 rows)
236 237 238 239 240 241
</programlisting>
 </para>

 <para>
  We can also access arbitrary rectangular slices of an array, or
  subarrays.  An array slice is denoted by writing
242
  <literal><replaceable>lower-bound</replaceable>:<replaceable>upper-bound</replaceable></literal>
243
  for one or more array dimensions.  For example, this query retrieves the first
244
  item on Bill's schedule for the first two days of the week:
245
     
246
<programlisting>
247
SELECT schedule[1:2][1:1] FROM sal_emp WHERE name = 'Bill';
248

249 250
      schedule
--------------------
251
 {{meeting},{""}}
252
(1 row)
253
</programlisting>
254

255
  We could also have written
256

257
<programlisting>
258
SELECT schedule[1:2][1] FROM sal_emp WHERE name = 'Bill';
259
</programlisting>
260

261
  with the same result.  An array subscripting operation is always taken to
262
  represent an array slice if any of the subscripts are written in the form
263 264
  <literal><replaceable>lower</replaceable>:<replaceable>upper</replaceable></literal>.
  A lower bound of 1 is assumed for any subscript where only one value
265
  is specified, as in this example:
266 267 268 269 270 271 272 273 274 275
<programlisting>
SELECT schedule[1:2][2] FROM sal_emp WHERE name = 'Bill';
         schedule
---------------------------
 {{meeting,lunch},{"",""}}
(1 row)
</programlisting>
 </para>

 <para>
276 277 278
  The current dimensions of any array value can be retrieved with the
  <function>array_dims</function> function:

279
<programlisting>
280 281 282 283 284 285 286 287 288 289 290 291 292 293 294 295 296 297 298 299 300
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.  Dimensions can also be retrieved with
  <function>array_upper</function> and <function>array_lower</function>,
  which return the upper and lower bound of a
  specified array dimension, respectively.

<programlisting>
SELECT array_upper(schedule, 1) FROM sal_emp WHERE name = 'Carol';

 array_upper
-------------
           2
301 302
(1 row)
</programlisting>
303
 </para>
304 305 306 307
 </sect2>

 <sect2>
  <title>Modifying Arrays</title>
308

309 310
 <para>
  An array value can be replaced completely:
311

312
<programlisting>
313 314
UPDATE sal_emp SET pay_by_quarter = '{25000,25000,27000,27000}'
    WHERE name = 'Carol';
315
</programlisting>
316

317
  or using the <literal>ARRAY</literal> expression syntax:
318 319 320 321 322 323 324

<programlisting>
UPDATE sal_emp SET pay_by_quarter = ARRAY[25000,25000,27000,27000]
    WHERE name = 'Carol';
</programlisting>

  An array may also be updated at a single element:
325

326
<programlisting>
327 328
UPDATE sal_emp SET pay_by_quarter[4] = 15000
    WHERE name = 'Bill';
329
</programListing>
330

331
  or updated in a slice:
332

333
<programlisting>
334 335
UPDATE sal_emp SET pay_by_quarter[1:2] = '{27000,27000}'
    WHERE name = 'Carol';
336
</programlisting>
337

338 339 340
 </para>

 <para>
341
  A stored array value can be enlarged by assigning to an element adjacent to
342
  those already present, or by assigning to a slice that is adjacent
343 344 345 346 347
  to or overlaps the data already present.  For example, if array
  <literal>myarray</> currently has 4 elements, it will have five
  elements after an update that assigns to <literal>myarray[5]</>.
  Currently, enlargement in this fashion is only allowed for one-dimensional
  arrays, not multidimensional arrays.
348 349
 </para>

350 351
 <para>
  Array slice assignment allows creation of arrays that do not use one-based
352
  subscripts.  For example one might assign to <literal>myarray[-2:7]</> to
353 354 355
  create an array with subscript values running from -2 to 7.
 </para>

356
 <para>
357 358
  New array values can also be constructed by using the concatenation operator,
  <literal>||</literal>.
359 360
<programlisting>
SELECT ARRAY[1,2] || ARRAY[3,4];
361 362 363
 ?column?
-----------
 {1,2,3,4}
364 365 366 367 368 369 370 371
(1 row)

SELECT ARRAY[5,6] || ARRAY[[1,2],[3,4]];
      ?column?
---------------------
 {{5,6},{1,2},{3,4}}
(1 row)
</programlisting>
372
 </para>
373

374
 <para>
375
  The concatenation operator allows a single element to be pushed on to the
376
  beginning or end of a one-dimensional array. It also accepts two
377
  <replaceable>N</>-dimensional arrays, or an <replaceable>N</>-dimensional
378 379
  and an <replaceable>N+1</>-dimensional array.
 </para>
380

381 382 383
 <para>
  When a single element is pushed on to the beginning of a one-dimensional
  array, the result is an array with a lower bound subscript equal to
384
  the right-hand operand's lower bound subscript, minus one. When a single
385
  element is pushed on to the end of a one-dimensional array, the result is
386
  an array retaining the lower bound of the left-hand operand. For example:
387
<programlisting>
388
SELECT array_dims(1 || ARRAY[2,3]);
389 390 391 392
 array_dims
------------
 [0:2]
(1 row)
393 394 395 396 397 398 399 400 401 402 403

SELECT array_dims(ARRAY[1,2] || 3);
 array_dims
------------
 [1:3]
(1 row)
</programlisting>
 </para>

 <para>
  When two arrays with an equal number of dimensions are concatenated, the
404 405 406
  result retains the lower bound subscript of the left-hand operand's outer
  dimension. The result is an array comprising every element of the left-hand
  operand followed by every element of the right-hand operand. For example:
407 408 409 410 411 412 413 414 415 416 417 418 419 420 421 422 423 424 425 426 427 428 429 430 431 432 433
<programlisting>
SELECT array_dims(ARRAY[1,2] || ARRAY[3,4,5]);
 array_dims
------------
 [1:5]
(1 row)

SELECT array_dims(ARRAY[[1,2],[3,4]] || ARRAY[[5,6],[7,8],[9,0]]);
 array_dims
------------
 [1:5][1:2]
(1 row)
</programlisting>
 </para>

 <para>
  When an <replaceable>N</>-dimensional array is pushed on to the beginning
  or end of an <replaceable>N+1</>-dimensional array, the result is
  analogous to the element-array case above. Each <replaceable>N</>-dimensional
  sub-array is essentially an element of the <replaceable>N+1</>-dimensional
  array's outer dimension. For example:
<programlisting>
SELECT array_dims(ARRAY[1,2] || ARRAY[[3,4],[5,6]]);
 array_dims
------------
 [0:2][1:2]
(1 row)
434 435 436 437
</programlisting>
 </para>

 <para>
438
  An array can also be constructed by using the functions
439 440 441 442 443 444 445 446 447 448 449 450 451 452 453 454 455 456 457 458 459 460 461
  <function>array_prepend</function>, <function>array_append</function>,
  or <function>array_cat</function>. The first two only support one-dimensional
  arrays, but <function>array_cat</function> supports multidimensional arrays.

  Note that the concatenation operator discussed above is preferred over
  direct use of these functions. In fact, the functions are primarily for use
  in implementing the concatenation operator. However, they may be directly
  useful in the creation of user-defined aggregates. Some examples:

<programlisting>
SELECT array_prepend(1, ARRAY[2,3]);
 array_prepend
---------------
 {1,2,3}
(1 row)

SELECT array_append(ARRAY[1,2], 3);
 array_append
--------------
 {1,2,3}
(1 row)

SELECT array_cat(ARRAY[1,2], ARRAY[3,4]);
462 463 464
 array_cat
-----------
 {1,2,3,4}
465 466 467 468 469 470 471 472 473 474 475 476 477 478
(1 row)

SELECT array_cat(ARRAY[[1,2],[3,4]], ARRAY[5,6]);
      array_cat
---------------------
 {{1,2},{3,4},{5,6}}
(1 row)

SELECT array_cat(ARRAY[5,6], ARRAY[[1,2],[3,4]]);
      array_cat
---------------------
 {{5,6},{1,2},{3,4}}
</programlisting>
 </para>
479 480 481 482
 </sect2>

 <sect2>
  <title>Searching in Arrays</title>
483 484 485

 <para>
  To search for a value in an array, you must check each value of the
486
  array. This can be done by hand, if you know the size of the array.
487
  For example:
488 489 490 491 492 493 494 495 496

<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
497 498 499
  helpful if the size of the array is uncertain. An alternative method is
  described in <xref linkend="functions-comparisons">. The above
  query could be replaced by:
500 501

<programlisting>
502
SELECT * FROM sal_emp WHERE 10000 = ANY (pay_by_quarter);
503 504 505
</programlisting>

  In addition, you could find rows where the array had all values
506
  equal to 10000 with:
507 508

<programlisting>
509
SELECT * FROM sal_emp WHERE 10000 = ALL (pay_by_quarter);
510 511 512 513 514 515
</programlisting>

 </para>

 <tip>
  <para>
516 517 518 519 520
   Arrays are not sets; searching for specific array elements
   may be a sign of database misdesign.  Consider
   using a separate table with a row for each item that would be an
   array element.  This will be easier to search, and is likely to
   scale up better to large numbers of elements.
521 522
  </para>
 </tip>
523
 </sect2>
524

525 526
 <sect2>
  <title>Array Input and Output Syntax</title>
527

528
  <para>
529
   The external text representation of an array value consists of items that
530 531 532 533 534 535
   are interpreted according to the I/O conversion rules for the array's
   element type, plus decoration that indicates the array structure.
   The decoration consists of curly braces (<literal>{</> and <literal>}</>)
   around the array value plus delimiter characters between adjacent items.
   The delimiter character is usually a comma (<literal>,</>) but can be
   something else: it is determined by the <literal>typdelim</> setting
536
   for the array's element type.  (Among the standard data types provided
537 538 539 540 541 542 543 544 545 546
   in the <productname>PostgreSQL</productname> distribution, type
   <literal>box</> uses a semicolon (<literal>;</>) but all the others
   use comma.)  In a multidimensional array, each dimension (row, plane,
   cube, etc.) gets its own level of curly braces, and delimiters
   must be written between adjacent curly-braced entities of the same level.
   You may write whitespace before a left brace, after a right
   brace, or before any individual item string.  Whitespace after an item
   is not ignored, however: after skipping leading whitespace, everything
   up to the next right brace or delimiter is taken as the item value.
  </para>
547 548

  <para>
549
   As shown previously, when writing an array value you may write double
550 551 552
   quotes around any individual array
   element.  You <emphasis>must</> do so if the element value would otherwise
   confuse the array-value parser.  For example, elements containing curly
553 554
   braces, commas (or whatever the delimiter character is), double quotes,
   backslashes, or leading white space must be double-quoted.  To put a double
555 556
   quote or backslash in a quoted array element value, precede it with a
   backslash.
557 558
   Alternatively, you can use backslash-escaping to protect all data characters
   that would otherwise be taken as array syntax or ignorable white space.
559 560
  </para>

561 562 563 564 565
  <para>
   The array output routine will put double quotes around element values
   if they are empty strings or contain curly braces, delimiter characters,
   double quotes, backslashes, or white space.  Double quotes and backslashes
   embedded in element values will be backslash-escaped.  For numeric
566 567
   data types it is safe to assume that double quotes will never appear, but
   for textual data types one should be prepared to cope with either presence
568 569 570 571
   or absence of quotes.  (This is a change in behavior from pre-7.2
   <productname>PostgreSQL</productname> releases.)
  </para>

572
 <note>
573
  <para>
574
   Remember that what you write in an SQL command will first be interpreted
575 576 577 578 579 580 581 582
   as a string literal, and then as an array.  This doubles the number of
   backslashes you need.  For example, to insert a <type>text</> array
   value containing a backslash and a double quote, you'd need to write
<programlisting>
INSERT ... VALUES ('{"\\\\","\\""}');
</programlisting>
   The string-literal processor removes one level of backslashes, so that
   what arrives at the array-value parser looks like <literal>{"\\","\""}</>.
583
   In turn, the strings fed to the <type>text</> data type's input routine
584
   become <literal>\</> and <literal>"</> respectively.  (If we were working
585
   with a data type whose input routine also treated backslashes specially,
586
   <type>bytea</> for example, we might need as many as eight backslashes
587
   in the command to get one backslash into the stored array element.)
588
  </para>
589
 </note>
590 591 592 593 594 595 596 597 598

 <tip>
  <para>
   The <literal>ARRAY</> constructor syntax is often easier to work with
   than the array-literal syntax when writing array values in SQL commands.
   In <literal>ARRAY</>, individual element values are written the same way
   they would be written when not members of an array.
  </para>
 </tip>
599
 </sect2>
600

601
</sect1>