Sophie

Sophie

distrib > Mandriva > 9.1 > ppc > by-pkgid > c87b2b497674629a1400410f06a9ef63 > files > 30

postgresql-docs-7.3.2-5mdk.ppc.rpm

<HTML
><HEAD
><TITLE
>Arrays</TITLE
><META
NAME="GENERATOR"
CONTENT="Modular DocBook HTML Stylesheet Version 1.73
"><LINK
REV="MADE"
HREF="mailto:pgsql-docs@postgresql.org"><LINK
REL="HOME"
TITLE="PostgreSQL 7.3.2 Documentation"
HREF="index.html"><LINK
REL="UP"
TITLE="Data Types"
HREF="datatype.html"><LINK
REL="PREVIOUS"
TITLE="Pseudo-Types"
HREF="datatype-pseudo.html"><LINK
REL="NEXT"
TITLE="Functions and Operators"
HREF="functions.html"><LINK
REL="STYLESHEET"
TYPE="text/css"
HREF="stylesheet.css"><META
NAME="creation"
CONTENT="2003-02-03T20:17:34"></HEAD
><BODY
CLASS="SECT1"
BGCOLOR="#FFFFFF"
TEXT="#000000"
LINK="#0000FF"
VLINK="#840084"
ALINK="#0000FF"
><DIV
CLASS="NAVHEADER"
><TABLE
SUMMARY="Header navigation table"
WIDTH="100%"
BORDER="0"
CELLPADDING="0"
CELLSPACING="0"
><TR
><TH
COLSPAN="3"
ALIGN="center"
>PostgreSQL 7.3.2 Documentation</TH
></TR
><TR
><TD
WIDTH="10%"
ALIGN="left"
VALIGN="bottom"
><A
HREF="datatype-pseudo.html"
ACCESSKEY="P"
>Prev</A
></TD
><TD
WIDTH="80%"
ALIGN="center"
VALIGN="bottom"
>Chapter 5. Data Types</TD
><TD
WIDTH="10%"
ALIGN="right"
VALIGN="bottom"
><A
HREF="functions.html"
ACCESSKEY="N"
>Next</A
></TD
></TR
></TABLE
><HR
ALIGN="LEFT"
WIDTH="100%"></DIV
><DIV
CLASS="SECT1"
><H1
CLASS="SECT1"
><A
NAME="ARRAYS"
>5.12. Arrays</A
></H1
><A
NAME="AEN4963"
></A
><P
>  <SPAN
CLASS="PRODUCTNAME"
>PostgreSQL</SPAN
> 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:
</P><PRE
CLASS="PROGRAMLISTING"
>CREATE TABLE sal_emp (
    name            text,
    pay_by_quarter  integer[],
    schedule        text[][]
);</PRE
><P>
  As shown, an array data type is named by appending square brackets
  (<TT
CLASS="LITERAL"
>[]</TT
>) to the data type name of the array elements.
  The above command will create a table named
  <TT
CLASS="STRUCTNAME"
>sal_emp</TT
> with columns including
  a <TT
CLASS="TYPE"
>text</TT
> string (<TT
CLASS="STRUCTFIELD"
>name</TT
>),
  a one-dimensional array of type
  <TT
CLASS="TYPE"
>integer</TT
> (<TT
CLASS="STRUCTFIELD"
>pay_by_quarter</TT
>),
  which represents the employee's salary by quarter, and a
  two-dimensional array of <TT
CLASS="TYPE"
>text</TT
>
  (<TT
CLASS="STRUCTFIELD"
>schedule</TT
>), which represents the
  employee's weekly schedule.
 </P
><P
>  Now we do some <TT
CLASS="COMMAND"
>INSERT</TT
>s.  Observe that to write an array
  value, we enclose the element values within curly braces and separate them
  by commas.  If you know C, this is not unlike the syntax for
  initializing structures.  (More details appear below.)
     
</P><PRE
CLASS="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"}}');</PRE
><P>
 </P
><P
>  Now, we can run some queries on <TT
CLASS="STRUCTNAME"
>sal_emp</TT
>.
  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:
     
</P><PRE
CLASS="PROGRAMLISTING"
>SELECT name FROM sal_emp WHERE pay_by_quarter[1] &lt;&gt; pay_by_quarter[2];

 name
-------
 Carol
(1 row)</PRE
><P>

  The array subscript numbers are written within square brackets.
  By default <SPAN
CLASS="PRODUCTNAME"
>PostgreSQL</SPAN
> uses the
  one-based numbering convention for arrays, that is,
  an array of <TT
CLASS="REPLACEABLE"
><I
>n</I
></TT
> elements starts with <TT
CLASS="LITERAL"
>array[1]</TT
> and
  ends with <TT
CLASS="LITERAL"
>array[<TT
CLASS="REPLACEABLE"
><I
>n</I
></TT
>]</TT
>.
 </P
><P
>  This query retrieves the third quarter pay of all employees:
     
</P><PRE
CLASS="PROGRAMLISTING"
>SELECT pay_by_quarter[3] FROM sal_emp;

 pay_by_quarter
----------------
          10000
          25000
(2 rows)</PRE
><P>
 </P
><P
>  We can also access arbitrary rectangular slices of an array, or
  subarrays.  An array slice is denoted by writing
  <TT
CLASS="LITERAL"
><TT
CLASS="REPLACEABLE"
><I
>lower-bound</I
></TT
>:<TT
CLASS="REPLACEABLE"
><I
>upper-bound</I
></TT
></TT
>
  for one or more array dimensions.  This query retrieves the first
  item on Bill's schedule for the first two days of the week:
     
</P><PRE
CLASS="PROGRAMLISTING"
>SELECT schedule[1:2][1:1] FROM sal_emp WHERE name = 'Bill';

      schedule
--------------------
 {{meeting},{""}}
(1 row)</PRE
><P>

  We could also have written

</P><PRE
CLASS="PROGRAMLISTING"
>SELECT schedule[1:2][1] FROM sal_emp WHERE name = 'Bill';</PRE
><P>

  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
  <TT
CLASS="LITERAL"
><TT
CLASS="REPLACEABLE"
><I
>lower</I
></TT
>:<TT
CLASS="REPLACEABLE"
><I
>upper</I
></TT
></TT
>.
  A lower bound of 1 is assumed for any subscript where only one value
  is specified.
 </P
><P
>  An array value can be replaced completely:

</P><PRE
CLASS="PROGRAMLISTING"
>UPDATE sal_emp SET pay_by_quarter = '{25000,25000,27000,27000}'
    WHERE name = 'Carol';</PRE
><P>

  or updated at a single element:

</P><PRE
CLASS="PROGRAMLISTING"
>UPDATE sal_emp SET pay_by_quarter[4] = 15000
    WHERE name = 'Bill';</PRE
><P>

  or updated in a slice:

</P><PRE
CLASS="PROGRAMLISTING"
>UPDATE sal_emp SET pay_by_quarter[1:2] = '{27000,27000}'
    WHERE name = 'Carol';</PRE
><P>
 </P
><P
>  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 <TT
CLASS="LITERAL"
>array[5]</TT
>.  Currently, enlargement in
  this fashion is only allowed for one-dimensional arrays, not
  multidimensional arrays.
 </P
><P
>  Array slice assignment allows creation of arrays that do not use one-based
  subscripts.  For example one might assign to <TT
CLASS="LITERAL"
>array[-2:7]</TT
> to
  create an array with subscript values running from -2 to 7.
 </P
><P
>  The syntax for <TT
CLASS="COMMAND"
>CREATE TABLE</TT
> allows fixed-length
  arrays to be defined:

</P><PRE
CLASS="PROGRAMLISTING"
>CREATE TABLE tictactoe (
    squares   integer[3][3]
);</PRE
><P>

  However, the current implementation does not enforce the array size
  limits --- the behavior is the same as for arrays of unspecified
  length.
 </P
><P
>  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
  <TT
CLASS="COMMAND"
>CREATE TABLE</TT
> is simply documentation, it does not
  affect runtime behavior.
 </P
><P
>  The current dimensions of any array value can be retrieved with the
  <TT
CLASS="FUNCTION"
>array_dims</TT
> function:

</P><PRE
CLASS="PROGRAMLISTING"
>SELECT array_dims(schedule) FROM sal_emp WHERE name = 'Carol';

 array_dims
------------
 [1:2][1:1]
(1 row)</PRE
><P>

  <TT
CLASS="FUNCTION"
>array_dims</TT
> produces a <TT
CLASS="TYPE"
>text</TT
> result,
  which is convenient for people to read but perhaps not so convenient
  for programs.
 </P
><P
>  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):

</P><PRE
CLASS="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;</PRE
><P>

  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 <SPAN
CLASS="PRODUCTNAME"
>PostgreSQL</SPAN
> distribution,
  there is an extension available that defines new functions and
  operators for iterating over array values. Using this, the above
  query could be:

</P><PRE
CLASS="PROGRAMLISTING"
>SELECT * FROM sal_emp WHERE pay_by_quarter[1:4] *= 10000;</PRE
><P>

  To search the entire array (not just specified columns), you could
  use:

</P><PRE
CLASS="PROGRAMLISTING"
>SELECT * FROM sal_emp WHERE pay_by_quarter *= 10000;</PRE
><P>

  In addition, you could find rows where the array had all values
  equal to 10 000 with:

</P><PRE
CLASS="PROGRAMLISTING"
>SELECT * FROM sal_emp WHERE pay_by_quarter **= 10000;</PRE
><P>

  To install this optional module, look in the
  <TT
CLASS="FILENAME"
>contrib/array</TT
> directory of the
  <SPAN
CLASS="PRODUCTNAME"
>PostgreSQL</SPAN
> source distribution.
 </P
><DIV
CLASS="TIP"
><BLOCKQUOTE
CLASS="TIP"
><P
><B
>Tip: </B
>   Arrays are not sets; 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.
  </P
></BLOCKQUOTE
></DIV
><DIV
CLASS="NOTE"
><BLOCKQUOTE
CLASS="NOTE"
><P
><B
>Note: </B
>   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.  Fixing this is on the to-do list.
  </P
></BLOCKQUOTE
></DIV
><DIV
CLASS="FORMALPARA"
><P
><B
>Array input and output syntax. </B
>   The external representation of an array value consists of items that
   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 (<TT
CLASS="LITERAL"
>{</TT
> and <TT
CLASS="LITERAL"
>}</TT
>)
   around the array value plus delimiter characters between adjacent items.
   The delimiter character is usually a comma (<TT
CLASS="LITERAL"
>,</TT
>) but can be
   something else: it is determined by the <TT
CLASS="LITERAL"
>typdelim</TT
> setting
   for the array's element type.  (Among the standard data types provided
   in the <SPAN
CLASS="PRODUCTNAME"
>PostgreSQL</SPAN
> distribution, type
   <TT
CLASS="LITERAL"
>box</TT
> uses a semicolon (<TT
CLASS="LITERAL"
>;</TT
>) 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.
  </P
></DIV
><DIV
CLASS="FORMALPARA"
><P
><B
>Quoting array elements. </B
>   As shown above, when writing an array value you may write double
   quotes around any individual array
   element.  You <SPAN
CLASS="emphasis"
><I
CLASS="EMPHASIS"
>must</I
></SPAN
> do so if the element value would otherwise
   confuse the array-value parser.  For example, elements containing curly
   braces, commas (or whatever the delimiter character is), double quotes,
   backslashes, or leading white space must be double-quoted.  To put a double
   quote or backslash in an array element value, precede it with a backslash.
   Alternatively, you can use backslash-escaping to protect all data characters
   that would otherwise be taken as array syntax or ignorable white space.
  </P
></DIV
><P
>   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
   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
   or absence of quotes.  (This is a change in behavior from pre-7.2
   <SPAN
CLASS="PRODUCTNAME"
>PostgreSQL</SPAN
> releases.)
  </P
><DIV
CLASS="TIP"
><BLOCKQUOTE
CLASS="TIP"
><P
><B
>Tip: </B
>   Remember that what you write in an SQL command will first be interpreted
   as a string literal, and then as an array.  This doubles the number of
   backslashes you need.  For example, to insert a <TT
CLASS="TYPE"
>text</TT
> array
   value containing a backslash and a double quote, you'd need to write
</P><PRE
CLASS="PROGRAMLISTING"
>INSERT ... VALUES ('{"\\\\","\\""}');</PRE
><P>
   The string-literal processor removes one level of backslashes, so that
   what arrives at the array-value parser looks like <TT
CLASS="LITERAL"
>{"\\","\""}</TT
>.
   In turn, the strings fed to the <TT
CLASS="TYPE"
>text</TT
> data type's input routine
   become <TT
CLASS="LITERAL"
>\</TT
> and <TT
CLASS="LITERAL"
>"</TT
> respectively.  (If we were working
   with a data type whose input routine also treated backslashes specially,
   <TT
CLASS="TYPE"
>bytea</TT
> for example, we might need as many as eight backslashes
   in the command to get one backslash into the stored array element.)
  </P
></BLOCKQUOTE
></DIV
></DIV
><DIV
CLASS="NAVFOOTER"
><HR
ALIGN="LEFT"
WIDTH="100%"><TABLE
SUMMARY="Footer navigation table"
WIDTH="100%"
BORDER="0"
CELLPADDING="0"
CELLSPACING="0"
><TR
><TD
WIDTH="33%"
ALIGN="left"
VALIGN="top"
><A
HREF="datatype-pseudo.html"
ACCESSKEY="P"
>Prev</A
></TD
><TD
WIDTH="34%"
ALIGN="center"
VALIGN="top"
><A
HREF="index.html"
ACCESSKEY="H"
>Home</A
></TD
><TD
WIDTH="33%"
ALIGN="right"
VALIGN="top"
><A
HREF="functions.html"
ACCESSKEY="N"
>Next</A
></TD
></TR
><TR
><TD
WIDTH="33%"
ALIGN="left"
VALIGN="top"
>Pseudo-Types</TD
><TD
WIDTH="34%"
ALIGN="center"
VALIGN="top"
><A
HREF="datatype.html"
ACCESSKEY="U"
>Up</A
></TD
><TD
WIDTH="33%"
ALIGN="right"
VALIGN="top"
>Functions and Operators</TD
></TR
></TABLE
></DIV
></BODY
></HTML
>