<!--
$PostgreSQL: pgsql/doc/src/sgml/func.sgml,v 1.254 2005/06/13 02:40:04 neilc Exp $
PostgreSQL documentation
-->

 <chapter id="functions">
  <title>Functions and Operators</title>

  <indexterm zone="functions">
   <primary>function</primary>
  </indexterm>

  <indexterm zone="functions">
   <primary>operator</primary>
  </indexterm>

  <para>
   <productname>PostgreSQL</productname> provides a large number of
   functions and operators for the built-in data types.  Users can also
   define their own functions and operators, as described in
   <xref linkend="server-programming">.  The
   <application>psql</application> commands <command>\df</command> and
   <command>\do</command> can be used to show the list of all actually
   available functions and operators, respectively.
  </para>

  <para>
   If you are concerned about portability then take note that most of
   the functions and operators described in this chapter, with the
   exception of the most trivial arithmetic and comparison operators
   and some explicitly marked functions, are not specified by the
   <acronym>SQL</acronym> standard. Some of the extended functionality
   is present in other <acronym>SQL</acronym> database management
   systems, and in many cases this functionality is compatible and
   consistent between the various implementations.  This chapter is also
   not exhaustive;  additional functions appear in relevant sections of 
   the manual.
  </para>


  <sect1 id="functions-logical">
   <title>Logical Operators</title>

   <indexterm zone="functions-logical">
    <primary>operator</primary>
    <secondary>logical</secondary>
   </indexterm>

   <indexterm>
    <primary>Boolean</primary>
    <secondary>operators</secondary>
    <see>operators, logical</see>
   </indexterm>

   <para>
    The usual logical operators are available:

    <indexterm>
     <primary>AND (operator)</primary>
    </indexterm>

    <indexterm>
     <primary>OR (operator)</primary>
    </indexterm>

    <indexterm>
     <primary>NOT (operator)</primary>
    </indexterm>

    <indexterm>
     <primary>conjunction</primary>
    </indexterm>

    <indexterm>
     <primary>disjunction</primary>
    </indexterm>

    <indexterm>
     <primary>negation</primary>
    </indexterm>

    <simplelist>
     <member><literal>AND</></member>
     <member><literal>OR</></member>
     <member><literal>NOT</></member>
    </simplelist>

    <acronym>SQL</acronym> uses a three-valued Boolean logic where the null value represents
    <quote>unknown</quote>.  Observe the following truth tables:

    <informaltable>
     <tgroup cols="4">
      <thead>
       <row>
        <entry><replaceable>a</replaceable></entry>
        <entry><replaceable>b</replaceable></entry>
        <entry><replaceable>a</replaceable> AND <replaceable>b</replaceable></entry>
        <entry><replaceable>a</replaceable> OR <replaceable>b</replaceable></entry>
       </row>
      </thead>

      <tbody>
       <row>
        <entry>TRUE</entry>
        <entry>TRUE</entry>
        <entry>TRUE</entry>
        <entry>TRUE</entry>
       </row>

       <row>
        <entry>TRUE</entry>
        <entry>FALSE</entry>
        <entry>FALSE</entry>
        <entry>TRUE</entry>
       </row>

       <row>
        <entry>TRUE</entry>
        <entry>NULL</entry>
        <entry>NULL</entry>
        <entry>TRUE</entry>
       </row>

       <row>
        <entry>FALSE</entry>
        <entry>FALSE</entry>
        <entry>FALSE</entry>
        <entry>FALSE</entry>
       </row>

       <row>
        <entry>FALSE</entry>
        <entry>NULL</entry>
        <entry>FALSE</entry>
        <entry>NULL</entry>
       </row>

       <row>
        <entry>NULL</entry>
        <entry>NULL</entry>
        <entry>NULL</entry>
        <entry>NULL</entry>
       </row>
      </tbody>
     </tgroup>
    </informaltable>

    <informaltable>
     <tgroup cols="2">
      <thead>
       <row>
        <entry><replaceable>a</replaceable></entry>
        <entry>NOT <replaceable>a</replaceable></entry>
       </row>
      </thead>

      <tbody>
       <row>
        <entry>TRUE</entry>
        <entry>FALSE</entry>
       </row>

       <row>
        <entry>FALSE</entry>
        <entry>TRUE</entry>
       </row>

       <row>
        <entry>NULL</entry>
        <entry>NULL</entry>
       </row>
      </tbody>
     </tgroup>
    </informaltable>
   </para>

   <para>
    The operators <literal>AND</literal> and <literal>OR</literal> are
    commutative, that is, you can switch the left and right operand
    without affecting the result.  But see <xref
    linkend="syntax-express-eval"> for more information about the
    order of evaluation of subexpressions.
   </para>
  </sect1>

  <sect1 id="functions-comparison">
   <title>Comparison Operators</title>

   <indexterm zone="functions-comparison">
    <primary>comparison</primary>
    <secondary>operators</secondary>
   </indexterm>

   <para>
    The usual comparison operators are available, shown in <xref
    linkend="functions-comparison-table">.
   </para>

   <table id="functions-comparison-table">
    <title>Comparison Operators</title>
    <tgroup cols="2">
     <thead>
      <row>
       <entry>Operator</entry>
       <entry>Description</entry>
      </row>
     </thead>

     <tbody>
      <row>
       <entry> <literal>&lt;</literal> </entry>
       <entry>less than</entry>
      </row>

      <row>
       <entry> <literal>&gt;</literal> </entry>
       <entry>greater than</entry>
      </row>

      <row>
       <entry> <literal>&lt;=</literal> </entry>
       <entry>less than or equal to</entry>
      </row>

      <row>
       <entry> <literal>&gt;=</literal> </entry>
       <entry>greater than or equal to</entry>
      </row>

      <row>
       <entry> <literal>=</literal> </entry>
       <entry>equal</entry>
      </row>

      <row>
       <entry> <literal>&lt;&gt;</literal> or <literal>!=</literal> </entry>
       <entry>not equal</entry>
      </row>
     </tbody>
    </tgroup>
   </table>

   <note>
    <para>
     The <literal>!=</literal> operator is converted to
     <literal>&lt;&gt;</literal> in the parser stage.  It is not
     possible to implement <literal>!=</literal> and
     <literal>&lt;&gt;</literal> operators that do different things.
    </para>
   </note>

   <para>
    Comparison operators are available for all data types where this
    makes sense.  All comparison operators are binary operators that
    return values of type <type>boolean</type>; expressions like
    <literal>1 &lt; 2 &lt; 3</literal> are not valid (because there is
    no <literal>&lt;</literal> operator to compare a Boolean value with
    <literal>3</literal>).
   </para>

   <para>
    <indexterm>
     <primary>BETWEEN</primary>
    </indexterm>
    In addition to the comparison operators, the special
    <token>BETWEEN</token> construct is available.<indexterm><primary>BETWEEN</primary></indexterm>
<synopsis>
<replaceable>a</replaceable> BETWEEN <replaceable>x</replaceable> AND <replaceable>y</replaceable>
</synopsis>
    is equivalent to
<synopsis>
<replaceable>a</replaceable> &gt;= <replaceable>x</replaceable> AND <replaceable>a</replaceable> &lt;= <replaceable>y</replaceable>
</synopsis>
    Similarly,
<synopsis>
<replaceable>a</replaceable> NOT BETWEEN <replaceable>x</replaceable> AND <replaceable>y</replaceable>
</synopsis>
    is equivalent to
<synopsis>
<replaceable>a</replaceable> &lt; <replaceable>x</replaceable> OR <replaceable>a</replaceable> &gt; <replaceable>y</replaceable>
</synopsis>
    There is no difference between the two respective forms apart from
    the <acronym>CPU</acronym> cycles required to rewrite the first one
    into the second one internally.
   </para>

   <para>
    <indexterm>
     <primary>IS NULL</primary>
    </indexterm>
    <indexterm>
     <primary>IS NOT NULL</primary>
    </indexterm>
    <indexterm>
     <primary>ISNULL</primary>
    </indexterm>
    <indexterm>
     <primary>NOTNULL</primary>
    </indexterm>
    To check whether a value is or is not null, use the constructs
<synopsis>
<replaceable>expression</replaceable> IS NULL
<replaceable>expression</replaceable> IS NOT NULL
</synopsis>
    or the equivalent, but nonstandard, constructs
<synopsis>
<replaceable>expression</replaceable> ISNULL
<replaceable>expression</replaceable> NOTNULL
</synopsis>
    <indexterm><primary>null value</primary><secondary>comparing</secondary></indexterm>
   </para>

   <para>
    Do <emphasis>not</emphasis> write
    <literal><replaceable>expression</replaceable> = NULL</literal>
    because <literal>NULL</> is not <quote>equal to</quote>
    <literal>NULL</>.  (The null value represents an unknown value,
    and it is not known whether two unknown values are equal.) This
    behavior conforms to the SQL standard.
   </para>

  <tip>
   <para>
    Some applications may expect that
    <literal><replaceable>expression</replaceable> = NULL</literal>
    returns true if <replaceable>expression</replaceable> evaluates to
    the null value.  It is highly recommended that these applications
    be modified to comply with the SQL standard. However, if that
    cannot be done the <xref linkend="guc-transform-null-equals">
    configuration variable is available. If it is enabled,
    <productname>PostgreSQL</productname> will convert <literal>x =
    NULL</literal> clauses to <literal>x IS NULL</literal>.  This was
    the default behavior in <productname>PostgreSQL</productname>
    releases 6.5 through 7.1.
   </para>
  </tip>

   <para>
    <indexterm>
     <primary>IS DISTINCT FROM</primary>
    </indexterm>
    The ordinary comparison operators yield null (signifying <quote>unknown</>)
    when either input is null.  Another way to do comparisons is with the
    <literal>IS DISTINCT FROM</literal> construct:
<synopsis>
<replaceable>expression</replaceable> IS DISTINCT FROM <replaceable>expression</replaceable>
</synopsis>
    For non-null inputs this is the same as the <literal>&lt;&gt;</> operator.
    However, when both inputs are null it will return false, and when just
    one input is null it will return true.  Thus it effectively acts as though
    null were a normal data value, rather than <quote>unknown</>.
   </para>

   <para>
    <indexterm>
     <primary>IS TRUE</primary>
    </indexterm>
    <indexterm>
     <primary>IS NOT TRUE</primary>
    </indexterm>
    <indexterm>
     <primary>IS FALSE</primary>
    </indexterm>
    <indexterm>
     <primary>IS NOT FALSE</primary>
    </indexterm>
    <indexterm>
     <primary>IS UNKNOWN</primary>
    </indexterm>
    <indexterm>
     <primary>IS NOT UNKNOWN</primary>
    </indexterm>
    Boolean values can also be tested using the constructs
<synopsis>
<replaceable>expression</replaceable> IS TRUE
<replaceable>expression</replaceable> IS NOT TRUE
<replaceable>expression</replaceable> IS FALSE
<replaceable>expression</replaceable> IS NOT FALSE
<replaceable>expression</replaceable> IS UNKNOWN
<replaceable>expression</replaceable> IS NOT UNKNOWN
</synopsis>
    These will always return true or false, never a null value, even when the
    operand is null.
    A null input is treated as the logical value <quote>unknown</>.
    Notice that <literal>IS UNKNOWN</> and <literal>IS NOT UNKNOWN</> are
    effectively the same as <literal>IS NULL</literal> and
    <literal>IS NOT NULL</literal>, respectively, except that the input
    expression must be of Boolean type.
   </para>
  </sect1>

  <sect1 id="functions-math">
   <title>Mathematical Functions and Operators</title>

   <para>
    Mathematical operators are provided for many
    <productname>PostgreSQL</productname> types. For types without
    common mathematical conventions for all possible permutations 
    (e.g., date/time types) we
    describe the actual behavior in subsequent sections.
   </para>

   <para>
    <xref linkend="functions-math-op-table"> shows the available mathematical operators.
   </para>

   <table id="functions-math-op-table">
    <title>Mathematical Operators</title>

    <tgroup cols="4">
     <thead>
      <row>
       <entry>Operator</entry>
       <entry>Description</entry>
       <entry>Example</entry>
       <entry>Result</entry>
      </row>
     </thead>

     <tbody>
      <row>
       <entry> <literal>+</literal> </entry>
       <entry>addition</entry>
       <entry><literal>2 + 3</literal></entry>
       <entry><literal>5</literal></entry>
      </row>

      <row>
       <entry> <literal>-</literal> </entry>
       <entry>subtraction</entry>
       <entry><literal>2 - 3</literal></entry>
       <entry><literal>-1</literal></entry>
      </row>

      <row>
       <entry> <literal>*</literal> </entry>
       <entry>multiplication</entry>
       <entry><literal>2 * 3</literal></entry>
       <entry><literal>6</literal></entry>
      </row>

      <row>
       <entry> <literal>/</literal> </entry>
       <entry>division (integer division truncates results)</entry>
       <entry><literal>4 / 2</literal></entry>
       <entry><literal>2</literal></entry>
      </row>

      <row>
       <entry> <literal>%</literal> </entry>
       <entry>modulo (remainder)</entry>
       <entry><literal>5 % 4</literal></entry>
       <entry><literal>1</literal></entry>
      </row>

      <row>
       <entry> <literal>^</literal> </entry>
       <entry>exponentiation</entry>
       <entry><literal>2.0 ^ 3.0</literal></entry>
       <entry><literal>8</literal></entry>
      </row>

      <row>
       <entry> <literal>|/</literal> </entry>
       <entry>square root</entry>
       <entry><literal>|/ 25.0</literal></entry>
       <entry><literal>5</literal></entry>
      </row>

      <row>
       <entry> <literal>||/</literal> </entry>
       <entry>cube root</entry>
       <entry><literal>||/ 27.0</literal></entry>
       <entry><literal>3</literal></entry>
      </row>

      <row>
       <entry> <literal>!</literal> </entry>
       <entry>factorial</entry>
       <entry><literal>5 !</literal></entry>
       <entry><literal>120</literal></entry>
      </row>

      <row>
       <entry> <literal>!!</literal> </entry>
       <entry>factorial (prefix operator)</entry>
       <entry><literal>!! 5</literal></entry>
       <entry><literal>120</literal></entry>
      </row>

      <row>
       <entry> <literal>@</literal> </entry>
       <entry>absolute value</entry>
       <entry><literal>@ -5.0</literal></entry>
       <entry><literal>5</literal></entry>
      </row>

      <row>
       <entry> <literal>&amp;</literal> </entry>
       <entry>bitwise AND</entry>
       <entry><literal>91 &amp; 15</literal></entry>
       <entry><literal>11</literal></entry>
      </row>

      <row>
       <entry> <literal>|</literal> </entry>
       <entry>bitwise OR</entry>
       <entry><literal>32 | 3</literal></entry>
       <entry><literal>35</literal></entry>
      </row>

      <row>
       <entry> <literal>#</literal> </entry>
       <entry>bitwise XOR</entry>
       <entry><literal>17 # 5</literal></entry>
       <entry><literal>20</literal></entry>
      </row>

      <row>
       <entry> <literal>~</literal> </entry>
       <entry>bitwise NOT</entry>
       <entry><literal>~1</literal></entry>
       <entry><literal>-2</literal></entry>
      </row>

      <row>
       <entry> <literal>&lt;&lt;</literal> </entry>
       <entry>bitwise shift left</entry>
       <entry><literal>1 &lt;&lt; 4</literal></entry>
       <entry><literal>16</literal></entry>
      </row>

      <row>
       <entry> <literal>&gt;&gt;</literal> </entry>
       <entry>bitwise shift right</entry>
       <entry><literal>8 &gt;&gt; 2</literal></entry>
       <entry><literal>2</literal></entry>
      </row>

     </tbody>
    </tgroup>
   </table>

   <para>
    The bitwise operators work only on integral data types, whereas
    the others are available for all numeric data types.  The bitwise
    operators are also available for the bit
    string types <type>bit</type> and <type>bit varying</type>, as
    shown in <xref linkend="functions-bit-string-op-table">.
   </para>

  <para>
   <xref linkend="functions-math-func-table"> shows the available
   mathematical functions.  In the table, <literal>dp</literal>
   indicates <type>double precision</type>.  Many of these functions
   are provided in multiple forms with different argument types.
   Except where noted, any given form of a function returns the same
   data type as its argument.
   The functions working with <type>double precision</type> data are mostly
   implemented on top of the host system's C library; accuracy and behavior in
   boundary cases may therefore vary depending on the host system.
  </para>

   <table id="functions-math-func-table">
    <title>Mathematical Functions</title>
    <tgroup cols="5">
     <thead>
      <row>
       <entry>Function</entry>
       <entry>Return Type</entry>
       <entry>Description</entry>
       <entry>Example</entry>
       <entry>Result</entry>
      </row>
     </thead>

     <tbody>
      <row>
       <entry><literal><function>abs</>(<replaceable>x</replaceable>)</literal></entry>
       <entry>(same as <replaceable>x</>)</entry>
       <entry>absolute value</entry>
       <entry><literal>abs(-17.4)</literal></entry>
       <entry><literal>17.4</literal></entry>
      </row>

      <row>
       <entry><literal><function>cbrt</function>(<type>dp</type>)</literal></entry>
       <entry><type>dp</type></entry>
       <entry>cube root</entry>
       <entry><literal>cbrt(27.0)</literal></entry>
       <entry><literal>3</literal></entry>
      </row>

      <row>
       <entry><literal><function>ceil</function>(<type>dp</type> or <type>numeric</type>)</literal></entry>
       <entry>(same as input)</entry>
       <entry>smallest integer not less than argument</entry>
       <entry><literal>ceil(-42.8)</literal></entry>
       <entry><literal>-42</literal></entry>
      </row>

      <row>
       <entry><literal><function>ceiling</function>(<type>dp</type> or <type>numeric</type>)</literal></entry>
       <entry>(same as input)</entry>
       <entry>smallest integer not less than argument (alias for <function>ceil</function>)</entry>
       <entry><literal>ceiling(-95.3)</literal></entry>
       <entry><literal>-95</literal></entry>
      </row>

      <row>
       <entry><literal><function>degrees</function>(<type>dp</type>)</literal></entry>
       <entry><type>dp</type></entry>
       <entry>radians to degrees</entry>
       <entry><literal>degrees(0.5)</literal></entry>
       <entry><literal>28.6478897565412</literal></entry>
      </row>

      <row>
       <entry><literal><function>exp</function>(<type>dp</type> or <type>numeric</type>)</literal></entry>
       <entry>(same as input)</entry>
       <entry>exponential</entry>
       <entry><literal>exp(1.0)</literal></entry>
       <entry><literal>2.71828182845905</literal></entry>
      </row>

      <row>
       <entry><literal><function>floor</function>(<type>dp</type> or <type>numeric</type>)</literal></entry>
       <entry>(same as input)</entry>
       <entry>largest integer not greater than argument</entry>
       <entry><literal>floor(-42.8)</literal></entry>
       <entry><literal>-43</literal></entry>
      </row>

      <row>
       <entry><literal><function>ln</function>(<type>dp</type> or <type>numeric</type>)</literal></entry>
       <entry>(same as input)</entry>
       <entry>natural logarithm</entry>
       <entry><literal>ln(2.0)</literal></entry>
       <entry><literal>0.693147180559945</literal></entry>
      </row>

      <row>
       <entry><literal><function>log</function>(<type>dp</type> or <type>numeric</type>)</literal></entry>
       <entry>(same as input)</entry>
       <entry>base 10 logarithm</entry>
       <entry><literal>log(100.0)</literal></entry>
       <entry><literal>2</literal></entry>
      </row>

      <row>
       <entry><literal><function>log</function>(<parameter>b</parameter> <type>numeric</type>,
        <parameter>x</parameter> <type>numeric</type>)</literal></entry>
       <entry><type>numeric</type></entry>
       <entry>logarithm to base <parameter>b</parameter></entry>
       <entry><literal>log(2.0, 64.0)</literal></entry>
       <entry><literal>6.0000000000</literal></entry>
      </row>

      <row>
       <entry><literal><function>mod</function>(<parameter>y</parameter>,
        <parameter>x</parameter>)</literal></entry>
       <entry>(same as argument types)</entry>
       <entry>remainder of <parameter>y</parameter>/<parameter>x</parameter></entry>
       <entry><literal>mod(9,4)</literal></entry>
       <entry><literal>1</literal></entry>
      </row>

      <row>
       <entry><literal><function>pi</function>()</literal></entry>
       <entry><type>dp</type></entry>
       <entry><quote>&pi;</quote> constant</entry>
       <entry><literal>pi()</literal></entry>
       <entry><literal>3.14159265358979</literal></entry>
      </row>

      <row>
       <entry><literal><function>power</function>(<parameter>a</parameter> <type>dp</type>,
        <parameter>b</parameter> <type>dp</type>)</literal></entry>
       <entry><type>dp</type></entry>
       <entry><parameter>a</> raised to the power of <parameter>b</parameter></entry>
       <entry><literal>power(9.0, 3.0)</literal></entry>
       <entry><literal>729</literal></entry>
      </row>

      <row>
       <entry><literal><function>power</function>(<parameter>a</parameter> <type>numeric</type>,
        <parameter>b</parameter> <type>numeric</type>)</literal></entry>
       <entry><type>numeric</type></entry>
       <entry><parameter>a</> raised to the power of <parameter>b</parameter></entry>
       <entry><literal>power(9.0, 3.0)</literal></entry>
       <entry><literal>729</literal></entry>
      </row>

      <row>
       <entry><literal><function>radians</function>(<type>dp</type>)</literal></entry>
       <entry><type>dp</type></entry>
       <entry>degrees to radians</entry>
       <entry><literal>radians(45.0)</literal></entry>
       <entry><literal>0.785398163397448</literal></entry>
      </row>

      <row>
       <entry><literal><function>random</function>()</literal></entry>
       <entry><type>dp</type></entry>
       <entry>random value between 0.0 and 1.0</entry>
       <entry><literal>random()</literal></entry>
       <entry></entry>
      </row>

      <row>
       <entry><literal><function>round</function>(<type>dp</type> or <type>numeric</type>)</literal></entry>
       <entry>(same as input)</entry>
       <entry>round to nearest integer</entry>
       <entry><literal>round(42.4)</literal></entry>
       <entry><literal>42</literal></entry>
      </row>

      <row>
       <entry><literal><function>round</function>(<parameter>v</parameter> <type>numeric</type>, <parameter>s</parameter> <type>integer</type>)</literal></entry>
       <entry><type>numeric</type></entry>
       <entry>round to <parameter>s</parameter> decimal places</entry>
       <entry><literal>round(42.4382, 2)</literal></entry>
       <entry><literal>42.44</literal></entry>
      </row>

      <row>
       <entry><literal><function>setseed</function>(<type>dp</type>)</literal></entry>
       <entry><type>integer</type></entry>
       <entry>set seed for subsequent <literal>random()</literal> calls</entry>
       <entry><literal>setseed(0.54823)</literal></entry>
       <entry><literal>1177314959</literal></entry>
      </row>

      <row>
       <entry><literal><function>sign</function>(<type>dp</type> or <type>numeric</type>)</literal></entry>
       <entry>(same as input)</entry>
       <entry>sign of the argument (-1, 0, +1)</entry>
       <entry><literal>sign(-8.4)</literal></entry>
       <entry><literal>-1</literal></entry>
      </row>

      <row>
       <entry><literal><function>sqrt</function>(<type>dp</type> or <type>numeric</type>)</literal></entry>
       <entry>(same as input)</entry>
       <entry>square root</entry>
       <entry><literal>sqrt(2.0)</literal></entry>
       <entry><literal>1.4142135623731</literal></entry>
      </row>

      <row>
       <entry><literal><function>trunc</function>(<type>dp</type> or <type>numeric</type>)</literal></entry>
       <entry>(same as input)</entry>
       <entry>truncate toward zero</entry>
       <entry><literal>trunc(42.8)</literal></entry>
       <entry><literal>42</literal></entry>
      </row>

      <row>
       <entry><literal><function>trunc</function>(<parameter>v</parameter> <type>numeric</type>, <parameter>s</parameter> <type>integer</type>)</literal></entry>
       <entry><type>numeric</type></entry>
       <entry>truncate to <parameter>s</parameter> decimal places</entry>
       <entry><literal>trunc(42.4382, 2)</literal></entry>
       <entry><literal>42.43</literal></entry>
      </row>

      <row>
       <entry><literal><function>width_bucket</function>(<parameter>op</parameter> <type>numeric</type>, <parameter>b1</parameter> <type>numeric</type>, <parameter>b2</parameter> <type>numeric</type>, <parameter>count</parameter> <type>integer</type>)</literal></entry>
       <entry><type>integer</type></entry>
       <entry>return the bucket to which <parameter>operand</> would
       be assigned in an equidepth histogram with <parameter>count</>
       buckets, an upper bound of <parameter>b1</>, and a lower bound
       of <parameter>b2</></entry>
       <entry><literal>width_bucket(5.35, 0.024, 10.06, 5)</literal></entry>
       <entry><literal>3</literal></entry>
      </row>
     </tbody>
    </tgroup>
   </table>

  <para>
   Finally, <xref linkend="functions-math-trig-table"> shows the
   available trigonometric functions.  All trigonometric functions
   take arguments and return values of type <type>double
   precision</type>.
  </para>

   <table id="functions-math-trig-table">
    <title>Trigonometric Functions</title>

    <tgroup cols="2">
     <thead>
      <row>
       <entry>Function</entry>
       <entry>Description</entry>
      </row>
     </thead>

     <tbody>
      <row>
       <entry><literal><function>acos</function>(<replaceable>x</replaceable>)</literal></entry>
       <entry>inverse cosine</entry>
      </row>

      <row>
       <entry><literal><function>asin</function>(<replaceable>x</replaceable>)</literal></entry>
       <entry>inverse sine</entry>
      </row>

      <row>
       <entry><literal><function>atan</function>(<replaceable>x</replaceable>)</literal></entry>
       <entry>inverse tangent</entry>
      </row>

      <row>
       <entry><literal><function>atan2</function>(<replaceable>x</replaceable>,
        <replaceable>y</replaceable>)</literal></entry>
       <entry>inverse tangent of
        <literal><replaceable>x</replaceable>/<replaceable>y</replaceable></literal></entry>
      </row>

      <row>
       <entry><literal><function>cos</function>(<replaceable>x</replaceable>)</literal></entry>
       <entry>cosine</entry>
      </row>

      <row>
       <entry><literal><function>cot</function>(<replaceable>x</replaceable>)</literal></entry>
       <entry>cotangent</entry>
      </row>

      <row>
       <entry><literal><function>sin</function>(<replaceable>x</replaceable>)</literal></entry>
       <entry>sine</entry>
      </row>

      <row>
       <entry><literal><function>tan</function>(<replaceable>x</replaceable>)</literal></entry>
       <entry>tangent</entry>
      </row>
     </tbody>
    </tgroup>
   </table>

  </sect1>


  <sect1 id="functions-string">
   <title>String Functions and Operators</title>

   <para>
    This section describes functions and operators for examining and
    manipulating string values.  Strings in this context include values
    of all the types <type>character</type>, <type>character
     varying</type>, and <type>text</type>.  Unless otherwise noted, all
    of the functions listed below work on all of these types, but be
    wary of potential effects of the automatic padding when using the
    <type>character</type> type.  Generally, the functions described
    here also work on data of non-string types by converting that data
    to a string representation first.  Some functions also exist
    natively for the bit-string types.
   </para>

   <para>
    <acronym>SQL</acronym> defines some string functions with a special syntax where
    certain key words rather than commas are used to separate the
    arguments.  Details are in <xref linkend="functions-string-sql">.
    These functions are also implemented using the regular syntax for
    function invocation.  (See <xref linkend="functions-string-other">.)
   </para>

   <table id="functions-string-sql">
    <title><acronym>SQL</acronym> String Functions and Operators</title>
    <tgroup cols="5">
     <thead>
      <row>
       <entry>Function</entry>
       <entry>Return Type</entry>
       <entry>Description</entry>
       <entry>Example</entry>
       <entry>Result</entry>  
      </row>
     </thead>

     <tbody>
      <row>
       <entry><literal><parameter>string</parameter> <literal>||</literal>
        <parameter>string</parameter></literal></entry>
       <entry> <type>text</type> </entry>
       <entry>
        String concatenation
        <indexterm>
         <primary>character string</primary>
         <secondary>concatenation</secondary>
        </indexterm>
       </entry>
       <entry><literal>'Post' || 'greSQL'</literal></entry>
       <entry><literal>PostgreSQL</literal></entry>
      </row>

      <row>
       <entry><literal><function>bit_length</function>(<parameter>string</parameter>)</literal></entry>
       <entry><type>integer</type></entry>
       <entry>Number of bits in string</entry>
       <entry><literal>bit_length('jose')</literal></entry>
       <entry><literal>32</literal></entry>
      </row>

      <row>
       <entry><literal><function>char_length</function>(<parameter>string</parameter>)</literal> or <literal><function>character_length</function>(<parameter>string</parameter>)</literal></entry>
       <entry><type>integer</type></entry>
       <entry>
        Number of characters in string
        <indexterm>
         <primary>character string</primary>
         <secondary>length</secondary>
        </indexterm>
        <indexterm>
         <primary>length</primary>
         <secondary sortas="character string">of a character string</secondary>
         <see>character strings, length</see>
        </indexterm>
       </entry>
       <entry><literal>char_length('jose')</literal></entry>
       <entry><literal>4</literal></entry>
      </row>

      <row>
       <entry><literal><function>convert</function>(<parameter>string</parameter>
       using <parameter>conversion_name</parameter>)</literal></entry>
       <entry><type>text</type></entry>
       <entry>
        Change encoding using specified conversion name.  Conversions
        can be defined by <command>CREATE CONVERSION</command>.  Also
        there are some pre-defined conversion names. See <xref
        linkend="conversion-names"> for available conversion
        names.
       </entry>
       <entry><literal>convert('PostgreSQL' using iso_8859_1_to_utf8)</literal></entry>
       <entry><literal>'PostgreSQL'</literal> in UTF8 (Unicode, 8-bit) encoding</entry>
      </row>

      <row>
       <entry><literal><function>lower</function>(<parameter>string</parameter>)</literal></entry>
       <entry><type>text</type></entry>
       <entry>Convert string to lower case</entry>
       <entry><literal>lower('TOM')</literal></entry>
       <entry><literal>tom</literal></entry>
      </row>

      <row>
       <entry><literal><function>octet_length</function>(<parameter>string</parameter>)</literal></entry>
       <entry><type>integer</type></entry>
       <entry>Number of bytes in string</entry>
       <entry><literal>octet_length('jose')</literal></entry>
       <entry><literal>4</literal></entry>
      </row>

      <row>
       <entry><literal><function>overlay</function>(<parameter>string</parameter> placing <parameter>string</parameter> from <type>integer</type> <optional>for <type>integer</type></optional>)</literal></entry>
       <entry><type>text</type></entry>
       <entry>
        Replace substring
        <indexterm>
         <primary>overlay</primary>
        </indexterm>
       </entry>
       <entry><literal>overlay('Txxxxas' placing 'hom' from 2 for 4)</literal></entry>
       <entry><literal>Thomas</literal></entry>
      </row>

      <row>
       <entry><literal><function>position</function>(<parameter>substring</parameter> in <parameter>string</parameter>)</literal></entry>
       <entry><type>integer</type></entry>
       <entry>Location of specified substring</entry>
       <entry><literal>position('om' in 'Thomas')</literal></entry>
       <entry><literal>3</literal></entry>
      </row>

      <row>
       <entry><literal><function>substring</function>(<parameter>string</parameter> <optional>from <type>integer</type></optional> <optional>for <type>integer</type></optional>)</literal></entry>
       <entry><type>text</type></entry>
       <entry>
        Extract substring
        <indexterm>
         <primary>substring</primary>
        </indexterm>
       </entry>
       <entry><literal>substring('Thomas' from 2 for 3)</literal></entry>
       <entry><literal>hom</literal></entry>
      </row>

      <row>
       <entry><literal><function>substring</function>(<parameter>string</parameter> from <replaceable>pattern</replaceable>)</literal></entry>
       <entry><type>text</type></entry>
       <entry>
        Extract substring matching POSIX regular expression
        <indexterm>
         <primary>substring</primary>
        </indexterm>
       </entry>
       <entry><literal>substring('Thomas' from '...$')</literal></entry>
       <entry><literal>mas</literal></entry>
      </row>

      <row>
       <entry><literal><function>substring</function>(<parameter>string</parameter> from <replaceable>pattern</replaceable> for <replaceable>escape</replaceable>)</literal></entry>
       <entry><type>text</type></entry>
       <entry>
        Extract substring matching <acronym>SQL</acronym> regular
        expression
        <indexterm>
         <primary>substring</primary>
        </indexterm>
       </entry>
       <entry><literal>substring('Thomas' from '%#"o_a#"_' for '#')</literal></entry>
       <entry><literal>oma</literal></entry>
      </row>

      <row>
       <entry>
        <literal><function>trim</function>(<optional>leading | trailing | both</optional>
        <optional><parameter>characters</parameter></optional> from
        <parameter>string</parameter>)</literal>
       </entry>
       <entry><type>text</type></entry>
       <entry>
        Remove the longest string containing only the
        <parameter>characters</parameter> (a space by default) from the
        start/end/both ends of the <parameter>string</parameter>
       </entry>
       <entry><literal>trim(both 'x' from 'xTomxx')</literal></entry>
       <entry><literal>Tom</literal></entry>
      </row>

      <row>
       <entry><literal><function>upper</function>(<parameter>string</parameter>)</literal></entry>
       <entry><type>text</type></entry>
       <entry>Convert string to uppercase</entry>
       <entry><literal>upper('tom')</literal></entry>
       <entry><literal>TOM</literal></entry>
      </row>
     </tbody>
    </tgroup>
   </table>

   <para>
    Additional string manipulation functions are available and are
    listed in <xref linkend="functions-string-other">.  Some of them are used internally to implement the
    <acronym>SQL</acronym>-standard string functions listed in <xref linkend="functions-string-sql">.
   </para>

   <table id="functions-string-other">
    <title>Other String Functions</title>
    <tgroup cols="5">
     <thead>
      <row>
       <entry>Function</entry>
       <entry>Return Type</entry>
       <entry>Description</entry>
       <entry>Example</entry>
       <entry>Result</entry>
      </row>
     </thead>

     <tbody>
      <row>
       <entry><literal><function>ascii</function>(<type>text</type>)</literal></entry>
       <entry><type>integer</type></entry>
       <entry><acronym>ASCII</acronym> code of the first character of the argument</entry>
       <entry><literal>ascii('x')</literal></entry>
       <entry><literal>120</literal></entry>
      </row>

      <row>
       <entry><literal><function>btrim</function>(<parameter>string</parameter> <type>text</type>
       <optional>, <parameter>characters</parameter> <type>text</type></optional>)</literal></entry>
       <entry><type>text</type></entry>
       <entry>
        Remove the longest string consisting only of characters
        in <parameter>characters</parameter> (a space by default)
        from the start and end of <parameter>string</parameter>
       </entry>
       <entry><literal>btrim('xyxtrimyyx', 'xy')</literal></entry>
       <entry><literal>trim</literal></entry>
      </row>

      <row>
       <entry><literal><function>chr</function>(<type>integer</type>)</literal></entry>
       <entry><type>text</type></entry>
       <entry>Character with the given <acronym>ASCII</acronym> code</entry>
       <entry><literal>chr(65)</literal></entry>
       <entry><literal>A</literal></entry>
      </row>

      <row>
       <entry>
        <literal><function>convert</function>(<parameter>string</parameter>
        <type>text</type>,
        <optional><parameter>src_encoding</parameter> <type>name</type>,</optional>
        <parameter>dest_encoding</parameter> <type>name</type>)</literal>
       </entry>
       <entry><type>text</type></entry>
       <entry>
        Convert string to <parameter>dest_encoding</parameter>.
        The original encoding is specified by
        <parameter>src_encoding</parameter>.  If
        <parameter>src_encoding</parameter> is omitted, database
        encoding is assumed.
       </entry>
       <entry><literal>convert( 'text_in_utf8', 'UTF8', 'LATIN1')</literal></entry>
       <entry><literal>text_in_utf8</literal> represented in ISO 8859-1 encoding</entry>
      </row>

      <row>
       <entry>
        <literal><function>decode</function>(<parameter>string</parameter> <type>text</type>,
        <parameter>type</parameter> <type>text</type>)</literal>
       </entry>
       <entry><type>bytea</type></entry>
       <entry>
        Decode binary data from <parameter>string</parameter> previously 
        encoded with <function>encode</>.  Parameter type is same as in <function>encode</>.
       </entry>
       <entry><literal>decode('MTIzAAE=', 'base64')</literal></entry>
       <entry><literal>123\000\001</literal></entry>
      </row>       

      <row>
       <entry>
        <literal><function>encode</function>(<parameter>data</parameter> <type>bytea</type>,
        <parameter>type</parameter> <type>text</type>)</literal>
       </entry>
       <entry><type>text</type></entry>
       <entry>
        Encode binary data to <acronym>ASCII</acronym>-only representation.  Supported
        types are: <literal>base64</>, <literal>hex</>, <literal>escape</>.
       </entry>
       <entry><literal>encode( '123\\000\\001', 'base64')</literal></entry>
       <entry><literal>MTIzAAE=</literal></entry>
      </row>       

      <row>
       <entry><literal><function>initcap</function>(<type>text</type>)</literal></entry>
       <entry><type>text</type></entry>
       <entry>
        Convert the first letter of each word to uppercase and the
        rest to lowercase. Words are sequences of alphanumeric
        characters separated by non-alphanumeric characters.
       </entry>
       <entry><literal>initcap('hi THOMAS')</literal></entry>
       <entry><literal>Hi Thomas</literal></entry>
      </row>

      <row>
       <entry><literal><function>length</function>(<parameter>string</parameter> <type>text</type>)</literal></entry>
       <entry><type>integer</type></entry>
       <entry>
        Number of characters in <parameter>string</parameter>
        <indexterm>
         <primary>character string</primary>
         <secondary>length</secondary>
        </indexterm>
        <indexterm>
         <primary>length</primary>
         <secondary sortas="character string">of a character string</secondary>
         <see>character strings, length</see>
        </indexterm>
       </entry>
       <entry><literal>length('jose')</literal></entry>
       <entry><literal>4</literal></entry>
      </row>

      <row>
       <entry>
        <literal><function>lpad</function>(<parameter>string</parameter> <type>text</type>,
        <parameter>length</parameter> <type>integer</type>
        <optional>, <parameter>fill</parameter> <type>text</type></optional>)</literal>
       </entry>
       <entry><type>text</type></entry>
       <entry>
        Fill up the <parameter>string</parameter> to length
        <parameter>length</parameter> by prepending the characters
        <parameter>fill</parameter> (a space by default).  If the
        <parameter>string</parameter> is already longer than
        <parameter>length</parameter> then it is truncated (on the
        right).
       </entry>
       <entry><literal>lpad('hi', 5, 'xy')</literal></entry>
       <entry><literal>xyxhi</literal></entry>
      </row>

      <row>
       <entry><literal><function>ltrim</function>(<parameter>string</parameter> <type>text</type>
        <optional>, <parameter>characters</parameter> <type>text</type></optional>)</literal>
       </entry>
       <entry><type>text</type></entry>
       <entry>
        Remove the longest string containing only characters from
        <parameter>characters</parameter> (a space by default) from the start of
        <parameter>string</parameter>
       </entry>
       <entry><literal>ltrim('zzzytrim', 'xyz')</literal></entry>
       <entry><literal>trim</literal></entry>
      </row>

      <row>
       <entry><literal><function>md5</function>(<parameter>string</parameter> <type>text</type>)</literal></entry>
       <entry><type>text</type></entry>
       <entry>
        Calculates the MD5 hash of <parameter>string</parameter>,
        returning the result in hexadecimal
       </entry>
       <entry><literal>md5('abc')</literal></entry>
       <entry><literal>900150983cd24fb0 d6963f7d28e17f72</literal></entry>
      </row>

      <row>
       <entry><literal><function>pg_client_encoding</function>()</literal></entry>
       <entry><type>name</type></entry>
       <entry>
        Current client encoding name
       </entry>
       <entry><literal>pg_client_encoding()</literal></entry>
       <entry><literal>SQL_ASCII</literal></entry>
      </row>

      <row>
       <entry><literal><function>quote_ident</function>(<parameter>string</parameter> text)</literal><indexterm><primary>quote_ident</></></entry>
       <entry><type>text</type></entry>
       <entry>
        Return the given string suitably quoted to be used as an identifier
        in an <acronym>SQL</acronym> statement string.
        Quotes are added only if necessary (i.e., if the string contains
        non-identifier characters or would be case-folded).
        Embedded quotes are properly doubled.
       </entry>
       <entry><literal>quote_ident('Foo bar')</literal></entry>
       <entry><literal>"Foo bar"</literal></entry>
      </row>

      <row>
       <entry><literal><function>quote_literal</function>(<parameter>string</parameter> text)</literal><indexterm><primary>quote_literal</></></entry>
       <entry><type>text</type></entry>
       <entry>
        Return the given string suitably quoted to be used as a string literal
        in an <acronym>SQL</acronym> statement string.
        Embedded quotes and backslashes are properly doubled.
       </entry>
       <entry><literal>quote_literal( 'O\'Reilly')</literal></entry>
       <entry><literal>'O''Reilly'</literal></entry>
      </row>

      <row>
       <entry><literal><function>repeat</function>(<parameter>string</parameter> <type>text</type>, <parameter>number</parameter> <type>integer</type>)</literal></entry>
       <entry><type>text</type></entry>
       <entry>Repeat <parameter>string</parameter> the specified
       <parameter>number</parameter> of times</entry>
       <entry><literal>repeat('Pg', 4)</literal></entry>
       <entry><literal>PgPgPgPg</literal></entry>
      </row>

      <row>
       <entry><literal><function>replace</function>(<parameter>string</parameter> <type>text</type>,
       <parameter>from</parameter> <type>text</type>,
       <parameter>to</parameter> <type>text</type>)</literal></entry>
       <entry><type>text</type></entry>
       <entry>Replace all occurrences in <parameter>string</parameter> of substring
        <parameter>from</parameter> with substring <parameter>to</parameter>
       </entry>
       <entry><literal>replace( 'abcdefabcdef', 'cd', 'XX')</literal></entry>
       <entry><literal>abXXefabXXef</literal></entry>
      </row>

      <row>
       <entry>
        <literal><function>rpad</function>(<parameter>string</parameter> <type>text</type>,
        <parameter>length</parameter> <type>integer</type>
        <optional>, <parameter>fill</parameter> <type>text</type></optional>)</literal>
       </entry>
       <entry><type>text</type></entry>
       <entry>
        Fill up the <parameter>string</parameter> to length
        <parameter>length</parameter> by appending the characters
        <parameter>fill</parameter> (a space by default).  If the
        <parameter>string</parameter> is already longer than
        <parameter>length</parameter> then it is truncated.
       </entry>
       <entry><literal>rpad('hi', 5, 'xy')</literal></entry>
       <entry><literal>hixyx</literal></entry>
      </row>

      <row>
       <entry><literal><function>rtrim</function>(<parameter>string</parameter> <type>text</type>
        <optional>, <parameter>characters</parameter> <type>text</type></optional>)</literal>
       </entry>
       <entry><type>text</type></entry>
       <entry>
        Remove the longest string containing only characters from
        <parameter>characters</parameter> (a space by default) from the end of
        <parameter>string</parameter>
       </entry>
       <entry><literal>rtrim('trimxxxx', 'x')</literal></entry>
       <entry><literal>trim</literal></entry>
      </row>

      <row>
       <entry><literal><function>split_part</function>(<parameter>string</parameter> <type>text</type>,
       <parameter>delimiter</parameter> <type>text</type>,
       <parameter>field</parameter> <type>integer</type>)</literal></entry>
       <entry><type>text</type></entry>
       <entry>Split <parameter>string</parameter> on <parameter>delimiter</parameter>
        and return the given field (counting from one)
       </entry>
       <entry><literal>split_part( 'abc~@~def~@~ghi', '~@~', 2)</literal></entry>
       <entry><literal>def</literal></entry>
      </row>

      <row>
       <entry><literal><function>strpos</function>(<parameter>string</parameter>, <parameter>substring</parameter>)</literal></entry>
       <entry><type>text</type></entry>
       <entry>
        Location of specified substring (same as
        <literal>position(<parameter>substring</parameter> in
         <parameter>string</parameter>)</literal>, but note the reversed
        argument order)
       </entry>
       <entry><literal>strpos('high', 'ig')</literal></entry>
       <entry><literal>2</literal></entry>
      </row>

      <row>
       <entry><literal><function>substr</function>(<parameter>string</parameter>, <parameter>from</parameter> <optional>, <parameter>count</parameter></optional>)</literal></entry>
       <entry><type>text</type></entry>
       <entry>
        Extract substring (same as
        <literal>substring(<parameter>string</parameter> from <parameter>from</parameter> for <parameter>count</parameter>)</literal>)
       </entry>
       <entry><literal>substr('alphabet', 3, 2)</literal></entry>
       <entry><literal>ph</literal></entry>
      </row>

      <row>
       <entry><literal><function>to_ascii</function>(<type>text</type>
        <optional>, <parameter>encoding</parameter></optional>)</literal></entry>
       <entry><type>text</type></entry>

       <entry>
       Convert <parameter>text</parameter> to <acronym>ASCII</acronym> from another encoding
       <footnote>
        <para>
         The <function>to_ascii</function> function supports conversion from
         <literal>LATIN1</>, <literal>LATIN2</>, <literal>LATIN9</>,
         and <literal>WIN1250</> encodings only.
        </para>
       </footnote>
       </entry>

       <entry><literal>to_ascii('Karel')</literal></entry>
       <entry><literal>Karel</literal></entry>
      </row>

      <row>
       <entry><literal><function>to_hex</function>(<parameter>number</parameter> <type>integer</type>
       or <type>bigint</type>)</literal></entry>
       <entry><type>text</type></entry>
       <entry>Convert <parameter>number</parameter> to its equivalent hexadecimal
        representation
       </entry>
       <entry><literal>to_hex(2147483647)</literal></entry>
       <entry><literal>7fffffff</literal></entry>
      </row>

      <row>
       <entry>
        <literal><function>translate</function>(<parameter>string</parameter>
        <type>text</type>,
        <parameter>from</parameter> <type>text</type>,
        <parameter>to</parameter> <type>text</type>)</literal>
       </entry>
       <entry><type>text</type></entry>
       <entry>
        Any character in <parameter>string</parameter> that matches a
        character in the <parameter>from</parameter> set is replaced by
        the corresponding character in the <parameter>to</parameter>
        set
       </entry>
       <entry><literal>translate('12345', '14', 'ax')</literal></entry>
       <entry><literal>a23x5</literal></entry>
      </row>       
      
     </tbody>
    </tgroup>
   </table>


   <table id="conversion-names">
    <title>Built-in Conversions</title>
    <tgroup cols="3">
     <thead>
      <row>
       <entry>Conversion Name
        <footnote>
         <para>
          The conversion names follow a standard naming scheme: The
          official name of the source encoding with all
          non-alphanumeric characters replaced by underscores followed
          by <literal>_to_</literal> followed by the equally processed
          destination encoding name. Therefore the names might deviate
          from the customary encoding names.
         </para>
        </footnote>
       </entry>
       <entry>Source Encoding</entry>
       <entry>Destination Encoding</entry>
      </row>
     </thead>

     <tbody>
      <row>
       <entry><literal>ascii_to_mic</literal></entry>
       <entry><literal>SQL_ASCII</literal></entry>
       <entry><literal>MULE_INTERNAL</literal></entry>
      </row>

      <row>
       <entry><literal>ascii_to_utf8</literal></entry>
       <entry><literal>SQL_ASCII</literal></entry>
       <entry><literal>UTF8</literal></entry>
      </row>

      <row>
       <entry><literal>big5_to_euc_tw</literal></entry>
       <entry><literal>BIG5</literal></entry>
       <entry><literal>EUC_TW</literal></entry>
      </row>

      <row>
       <entry><literal>big5_to_mic</literal></entry>
       <entry><literal>BIG5</literal></entry>
       <entry><literal>MULE_INTERNAL</literal></entry>
      </row>

      <row>
       <entry><literal>big5_to_utf8</literal></entry>
       <entry><literal>BIG5</literal></entry>
       <entry><literal>UTF8</literal></entry>
      </row>

      <row>
       <entry><literal>euc_cn_to_mic</literal></entry>
       <entry><literal>EUC_CN</literal></entry>
       <entry><literal>MULE_INTERNAL</literal></entry>
      </row>

      <row>
       <entry><literal>euc_cn_to_utf8</literal></entry>
       <entry><literal>EUC_CN</literal></entry>
       <entry><literal>UTF8</literal></entry>
      </row>

      <row>
       <entry><literal>euc_jp_to_mic</literal></entry>
       <entry><literal>EUC_JP</literal></entry>
       <entry><literal>MULE_INTERNAL</literal></entry>
      </row>

      <row>
       <entry><literal>euc_jp_to_sjis</literal></entry>
       <entry><literal>EUC_JP</literal></entry>
       <entry><literal>SJIS</literal></entry>
      </row>

      <row>
       <entry><literal>euc_jp_to_utf8</literal></entry>
       <entry><literal>EUC_JP</literal></entry>
       <entry><literal>UTF8</literal></entry>
      </row>

      <row>
       <entry><literal>euc_kr_to_mic</literal></entry>
       <entry><literal>EUC_KR</literal></entry>
       <entry><literal>MULE_INTERNAL</literal></entry>
      </row>

      <row>
       <entry><literal>euc_kr_to_utf8</literal></entry>
       <entry><literal>EUC_KR</literal></entry>
       <entry><literal>UTF8</literal></entry>
      </row>

      <row>
       <entry><literal>euc_tw_to_big5</literal></entry>
       <entry><literal>EUC_TW</literal></entry>
       <entry><literal>BIG5</literal></entry>
      </row>

      <row>
       <entry><literal>euc_tw_to_mic</literal></entry>
       <entry><literal>EUC_TW</literal></entry>
       <entry><literal>MULE_INTERNAL</literal></entry>
      </row>

      <row>
       <entry><literal>euc_tw_to_utf8</literal></entry>
       <entry><literal>EUC_TW</literal></entry>
       <entry><literal>UTF8</literal></entry>
      </row>

      <row>
       <entry><literal>gb18030_to_utf8</literal></entry>
       <entry><literal>GB18030</literal></entry>
       <entry><literal>UTF8</literal></entry>
      </row>

      <row>
       <entry><literal>gbk_to_utf8</literal></entry>
       <entry><literal>GBK</literal></entry>
       <entry><literal>UTF8</literal></entry>
      </row>

      <row>
       <entry><literal>iso_8859_10_to_utf8</literal></entry>
       <entry><literal>LATIN6</literal></entry>
       <entry><literal>UTF8</literal></entry>
      </row>

      <row>
       <entry><literal>iso_8859_13_to_utf8</literal></entry>
       <entry><literal>LATIN7</literal></entry>
       <entry><literal>UTF8</literal></entry>
      </row>

      <row>
       <entry><literal>iso_8859_14_to_utf8</literal></entry>
       <entry><literal>LATIN8</literal></entry>
       <entry><literal>UTF8</literal></entry>
      </row>

      <row>
       <entry><literal>iso_8859_15_to_utf8</literal></entry>
       <entry><literal>LATIN9</literal></entry>
       <entry><literal>UTF8</literal></entry>
      </row>

      <row>
       <entry><literal>iso_8859_16_to_utf8</literal></entry>
       <entry><literal>LATIN10</literal></entry>
       <entry><literal>UTF8</literal></entry>
      </row>

      <row>
       <entry><literal>iso_8859_1_to_mic</literal></entry>
       <entry><literal>LATIN1</literal></entry>
       <entry><literal>MULE_INTERNAL</literal></entry>
      </row>

      <row>
       <entry><literal>iso_8859_1_to_utf8</literal></entry>
       <entry><literal>LATIN1</literal></entry>
       <entry><literal>UTF8</literal></entry>
      </row>

      <row>
       <entry><literal>iso_8859_2_to_mic</literal></entry>
       <entry><literal>LATIN2</literal></entry>
       <entry><literal>MULE_INTERNAL</literal></entry>
      </row>

      <row>
       <entry><literal>iso_8859_2_to_utf8</literal></entry>
       <entry><literal>LATIN2</literal></entry>
       <entry><literal>UTF8</literal></entry>
      </row>

      <row>
       <entry><literal>iso_8859_2_to_windows_1250</literal></entry>
       <entry><literal>LATIN2</literal></entry>
       <entry><literal>WIN1250</literal></entry>
      </row>

      <row>
       <entry><literal>iso_8859_3_to_mic</literal></entry>
       <entry><literal>LATIN3</literal></entry>
       <entry><literal>MULE_INTERNAL</literal></entry>
      </row>

      <row>
       <entry><literal>iso_8859_3_to_utf8</literal></entry>
       <entry><literal>LATIN3</literal></entry>
       <entry><literal>UTF8</literal></entry>
      </row>

      <row>
       <entry><literal>iso_8859_4_to_mic</literal></entry>
       <entry><literal>LATIN4</literal></entry>
       <entry><literal>MULE_INTERNAL</literal></entry>
      </row>

      <row>
       <entry><literal>iso_8859_4_to_utf8</literal></entry>
       <entry><literal>LATIN4</literal></entry>
       <entry><literal>UTF8</literal></entry>
      </row>

      <row>
       <entry><literal>iso_8859_5_to_koi8_r</literal></entry>
       <entry><literal>ISO_8859_5</literal></entry>
       <entry><literal>KOI8</literal></entry>
      </row>

      <row>
       <entry><literal>iso_8859_5_to_mic</literal></entry>
       <entry><literal>ISO_8859_5</literal></entry>
       <entry><literal>MULE_INTERNAL</literal></entry>
      </row>

      <row>
       <entry><literal>iso_8859_5_to_utf8</literal></entry>
       <entry><literal>ISO_8859_5</literal></entry>
       <entry><literal>UTF8</literal></entry>
      </row>

      <row>
       <entry><literal>iso_8859_5_to_windows_1251</literal></entry>
       <entry><literal>ISO_8859_5</literal></entry>
       <entry><literal>WIN1251</literal></entry>
      </row>

      <row>
       <entry><literal>iso_8859_5_to_windows_866</literal></entry>
       <entry><literal>ISO_8859_5</literal></entry>
       <entry><literal>WIN866</literal></entry>
      </row>

      <row>
       <entry><literal>iso_8859_6_to_utf8</literal></entry>
       <entry><literal>ISO_8859_6</literal></entry>
       <entry><literal>UTF8</literal></entry>
      </row>

      <row>
       <entry><literal>iso_8859_7_to_utf8</literal></entry>
       <entry><literal>ISO_8859_7</literal></entry>
       <entry><literal>UTF8</literal></entry>
      </row>

      <row>
       <entry><literal>iso_8859_8_to_utf8</literal></entry>
       <entry><literal>ISO_8859_8</literal></entry>
       <entry><literal>UTF8</literal></entry>
      </row>

      <row>
       <entry><literal>iso_8859_9_to_utf8</literal></entry>
       <entry><literal>LATIN5</literal></entry>
       <entry><literal>UTF8</literal></entry>
      </row>

      <row>
       <entry><literal>johab_to_utf8</literal></entry>
       <entry><literal>JOHAB</literal></entry>
       <entry><literal>UTF8</literal></entry>
      </row>

      <row>
       <entry><literal>koi8_r_to_iso_8859_5</literal></entry>
       <entry><literal>KOI8</literal></entry>
       <entry><literal>ISO_8859_5</literal></entry>
      </row>

      <row>
       <entry><literal>koi8_r_to_mic</literal></entry>
       <entry><literal>KOI8</literal></entry>
       <entry><literal>MULE_INTERNAL</literal></entry>
      </row>

      <row>
       <entry><literal>koi8_r_to_utf8</literal></entry>
       <entry><literal>KOI8</literal></entry>
       <entry><literal>UTF8</literal></entry>
      </row>

      <row>
       <entry><literal>koi8_r_to_windows_1251</literal></entry>
       <entry><literal>KOI8</literal></entry>
       <entry><literal>WIN1251</literal></entry>
      </row>

      <row>
       <entry><literal>koi8_r_to_windows_866</literal></entry>
       <entry><literal>KOI8</literal></entry>
       <entry><literal>WIN866</literal></entry>
      </row>

      <row>
       <entry><literal>mic_to_ascii</literal></entry>
       <entry><literal>MULE_INTERNAL</literal></entry>
       <entry><literal>SQL_ASCII</literal></entry>
      </row>

      <row>
       <entry><literal>mic_to_big5</literal></entry>
       <entry><literal>MULE_INTERNAL</literal></entry>
       <entry><literal>BIG5</literal></entry>
      </row>

      <row>
       <entry><literal>mic_to_euc_cn</literal></entry>
       <entry><literal>MULE_INTERNAL</literal></entry>
       <entry><literal>EUC_CN</literal></entry>
      </row>

      <row>
       <entry><literal>mic_to_euc_jp</literal></entry>
       <entry><literal>MULE_INTERNAL</literal></entry>
       <entry><literal>EUC_JP</literal></entry>
      </row>

      <row>
       <entry><literal>mic_to_euc_kr</literal></entry>
       <entry><literal>MULE_INTERNAL</literal></entry>
       <entry><literal>EUC_KR</literal></entry>
      </row>

      <row>
       <entry><literal>mic_to_euc_tw</literal></entry>
       <entry><literal>MULE_INTERNAL</literal></entry>
       <entry><literal>EUC_TW</literal></entry>
      </row>

      <row>
       <entry><literal>mic_to_iso_8859_1</literal></entry>
       <entry><literal>MULE_INTERNAL</literal></entry>
       <entry><literal>LATIN1</literal></entry>
      </row>

      <row>
       <entry><literal>mic_to_iso_8859_2</literal></entry>
       <entry><literal>MULE_INTERNAL</literal></entry>
       <entry><literal>LATIN2</literal></entry>
      </row>

      <row>
       <entry><literal>mic_to_iso_8859_3</literal></entry>
       <entry><literal>MULE_INTERNAL</literal></entry>
       <entry><literal>LATIN3</literal></entry>
      </row>

      <row>
       <entry><literal>mic_to_iso_8859_4</literal></entry>
       <entry><literal>MULE_INTERNAL</literal></entry>
       <entry><literal>LATIN4</literal></entry>
      </row>

      <row>
       <entry><literal>mic_to_iso_8859_5</literal></entry>
       <entry><literal>MULE_INTERNAL</literal></entry>
       <entry><literal>ISO_8859_5</literal></entry>
      </row>

      <row>
       <entry><literal>mic_to_koi8_r</literal></entry>
       <entry><literal>MULE_INTERNAL</literal></entry>
       <entry><literal>KOI8</literal></entry>
      </row>

      <row>
       <entry><literal>mic_to_sjis</literal></entry>
       <entry><literal>MULE_INTERNAL</literal></entry>
       <entry><literal>SJIS</literal></entry>
      </row>

      <row>
       <entry><literal>mic_to_windows_1250</literal></entry>
       <entry><literal>MULE_INTERNAL</literal></entry>
       <entry><literal>WIN1250</literal></entry>
      </row>

      <row>
       <entry><literal>mic_to_windows_1251</literal></entry>
       <entry><literal>MULE_INTERNAL</literal></entry>
       <entry><literal>WIN1251</literal></entry>
      </row>

      <row>
       <entry><literal>mic_to_windows_866</literal></entry>
       <entry><literal>MULE_INTERNAL</literal></entry>
       <entry><literal>WIN866</literal></entry>
      </row>

      <row>
       <entry><literal>sjis_to_euc_jp</literal></entry>
       <entry><literal>SJIS</literal></entry>
       <entry><literal>EUC_JP</literal></entry>
      </row>

      <row>
       <entry><literal>sjis_to_mic</literal></entry>
       <entry><literal>SJIS</literal></entry>
       <entry><literal>MULE_INTERNAL</literal></entry>
      </row>

      <row>
       <entry><literal>sjis_to_utf8</literal></entry>
       <entry><literal>SJIS</literal></entry>
       <entry><literal>UTF8</literal></entry>
      </row>

      <row>
       <entry><literal>tcvn_to_utf8</literal></entry>
       <entry><literal>WIN1258</literal></entry>
       <entry><literal>UTF8</literal></entry>
      </row>

      <row>
       <entry><literal>uhc_to_utf8</literal></entry>
       <entry><literal>UHC</literal></entry>
       <entry><literal>UTF8</literal></entry>
      </row>

      <row>
       <entry><literal>utf8_to_ascii</literal></entry>
       <entry><literal>UTF8</literal></entry>
       <entry><literal>SQL_ASCII</literal></entry>
      </row>

      <row>
       <entry><literal>utf8_to_big5</literal></entry>
       <entry><literal>UTF8</literal></entry>
       <entry><literal>BIG5</literal></entry>
      </row>

      <row>
       <entry><literal>utf8_to_euc_cn</literal></entry>
       <entry><literal>UTF8</literal></entry>
       <entry><literal>EUC_CN</literal></entry>
      </row>

      <row>
       <entry><literal>utf8_to_euc_jp</literal></entry>
       <entry><literal>UTF8</literal></entry>
       <entry><literal>EUC_JP</literal></entry>
      </row>

      <row>
       <entry><literal>utf8_to_euc_kr</literal></entry>
       <entry><literal>UTF8</literal></entry>
       <entry><literal>EUC_KR</literal></entry>
      </row>

      <row>
       <entry><literal>utf8_to_euc_tw</literal></entry>
       <entry><literal>UTF8</literal></entry>
       <entry><literal>EUC_TW</literal></entry>
      </row>

      <row>
       <entry><literal>utf8_to_gb18030</literal></entry>
       <entry><literal>UTF8</literal></entry>
       <entry><literal>GB18030</literal></entry>
      </row>

      <row>
       <entry><literal>utf8_to_gbk</literal></entry>
       <entry><literal>UTF8</literal></entry>
       <entry><literal>GBK</literal></entry>
      </row>

      <row>
       <entry><literal>utf8_to_iso_8859_1</literal></entry>
       <entry><literal>UTF8</literal></entry>
       <entry><literal>LATIN1</literal></entry>
      </row>

      <row>
       <entry><literal>utf8_to_iso_8859_10</literal></entry>
       <entry><literal>UTF8</literal></entry>
       <entry><literal>LATIN6</literal></entry>
      </row>

      <row>
       <entry><literal>utf8_to_iso_8859_13</literal></entry>
       <entry><literal>UTF8</literal></entry>
       <entry><literal>LATIN7</literal></entry>
      </row>

      <row>
       <entry><literal>utf8_to_iso_8859_14</literal></entry>
       <entry><literal>UTF8</literal></entry>
       <entry><literal>LATIN8</literal></entry>
      </row>

      <row>
       <entry><literal>utf8_to_iso_8859_15</literal></entry>
       <entry><literal>UTF8</literal></entry>
       <entry><literal>LATIN9</literal></entry>
      </row>

      <row>
       <entry><literal>utf8_to_iso_8859_16</literal></entry>
       <entry><literal>UTF8</literal></entry>
       <entry><literal>LATIN10</literal></entry>
      </row>

      <row>
       <entry><literal>utf8_to_iso_8859_2</literal></entry>
       <entry><literal>UTF8</literal></entry>
       <entry><literal>LATIN2</literal></entry>
      </row>

      <row>
       <entry><literal>utf8_to_iso_8859_3</literal></entry>
       <entry><literal>UTF8</literal></entry>
       <entry><literal>LATIN3</literal></entry>
      </row>

      <row>
       <entry><literal>utf8_to_iso_8859_4</literal></entry>
       <entry><literal>UTF8</literal></entry>
       <entry><literal>LATIN4</literal></entry>
      </row>

      <row>
       <entry><literal>utf8_to_iso_8859_5</literal></entry>
       <entry><literal>UTF8</literal></entry>
       <entry><literal>ISO_8859_5</literal></entry>
      </row>

      <row>
       <entry><literal>utf8_to_iso_8859_6</literal></entry>
       <entry><literal>UTF8</literal></entry>
       <entry><literal>ISO_8859_6</literal></entry>
      </row>

      <row>
       <entry><literal>utf8_to_iso_8859_7</literal></entry>
       <entry><literal>UTF8</literal></entry>
       <entry><literal>ISO_8859_7</literal></entry>
      </row>

      <row>
       <entry><literal>utf8_to_iso_8859_8</literal></entry>
       <entry><literal>UTF8</literal></entry>
       <entry><literal>ISO_8859_8</literal></entry>
      </row>

      <row>
       <entry><literal>utf8_to_iso_8859_9</literal></entry>
       <entry><literal>UTF8</literal></entry>
       <entry><literal>LATIN5</literal></entry>
      </row>

      <row>
       <entry><literal>utf8_to_johab</literal></entry>
       <entry><literal>UTF8</literal></entry>
       <entry><literal>JOHAB</literal></entry>
      </row>

      <row>
       <entry><literal>utf8_to_koi8_r</literal></entry>
       <entry><literal>UTF8</literal></entry>
       <entry><literal>KOI8</literal></entry>
      </row>

      <row>
       <entry><literal>utf8_to_sjis</literal></entry>
       <entry><literal>UTF8</literal></entry>
       <entry><literal>SJIS</literal></entry>
      </row>

      <row>
       <entry><literal>utf8_to_tcvn</literal></entry>
       <entry><literal>UTF8</literal></entry>
       <entry><literal>WIN1258</literal></entry>
      </row>

      <row>
       <entry><literal>utf8_to_uhc</literal></entry>
       <entry><literal>UTF8</literal></entry>
       <entry><literal>UHC</literal></entry>
      </row>

      <row>
       <entry><literal>utf8_to_windows_1250</literal></entry>
       <entry><literal>UTF8</literal></entry>
       <entry><literal>WIN1250</literal></entry>
      </row>

      <row>
       <entry><literal>utf8_to_windows_1251</literal></entry>
       <entry><literal>UTF8</literal></entry>
       <entry><literal>WIN1251</literal></entry>
      </row>

      <row>
       <entry><literal>utf8_to_windows_1252</literal></entry>
       <entry><literal>UTF8</literal></entry>
       <entry><literal>WIN1252</literal></entry>
      </row>

      <row>
       <entry><literal>utf8_to_windows_1256</literal></entry>
       <entry><literal>UTF8</literal></entry>
       <entry><literal>WIN1256</literal></entry>
      </row>

      <row>
       <entry><literal>utf8_to_windows_866</literal></entry>
       <entry><literal>UTF8</literal></entry>
       <entry><literal>WIN866</literal></entry>
      </row>

      <row>
       <entry><literal>utf8_to_windows_874</literal></entry>
       <entry><literal>UTF8</literal></entry>
       <entry><literal>WIN874</literal></entry>
      </row>

      <row>
       <entry><literal>windows_1250_to_iso_8859_2</literal></entry>
       <entry><literal>WIN1250</literal></entry>
       <entry><literal>LATIN2</literal></entry>
      </row>

      <row>
       <entry><literal>windows_1250_to_mic</literal></entry>
       <entry><literal>WIN1250</literal></entry>
       <entry><literal>MULE_INTERNAL</literal></entry>
      </row>

      <row>
       <entry><literal>windows_1250_to_utf8</literal></entry>
       <entry><literal>WIN1250</literal></entry>
       <entry><literal>UTF8</literal></entry>
      </row>

      <row>
       <entry><literal>windows_1251_to_iso_8859_5</literal></entry>
       <entry><literal>WIN1251</literal></entry>
       <entry><literal>ISO_8859_5</literal></entry>
      </row>

      <row>
       <entry><literal>windows_1251_to_koi8_r</literal></entry>
       <entry><literal>WIN1251</literal></entry>
       <entry><literal>KOI8</literal></entry>
      </row>

      <row>
       <entry><literal>windows_1251_to_mic</literal></entry>
       <entry><literal>WIN1251</literal></entry>
       <entry><literal>MULE_INTERNAL</literal></entry>
      </row>

      <row>
       <entry><literal>windows_1251_to_utf8</literal></entry>
       <entry><literal>WIN1251</literal></entry>
       <entry><literal>UTF8</literal></entry>
      </row>

      <row>
       <entry><literal>windows_1251_to_windows_866</literal></entry>
       <entry><literal>WIN1251</literal></entry>
       <entry><literal>WIN866</literal></entry>
      </row>

      <row>
       <entry><literal>windows_1252_to_utf8</literal></entry>
       <entry><literal>WIN1252</literal></entry>
       <entry><literal>UTF8</literal></entry>
      </row>

      <row>
       <entry><literal>windows_1256_to_utf8</literal></entry>
       <entry><literal>WIN1256</literal></entry>
       <entry><literal>UTF8</literal></entry>
      </row>

      <row>
       <entry><literal>windows_866_to_iso_8859_5</literal></entry>
       <entry><literal>WIN866</literal></entry>
       <entry><literal>ISO_8859_5</literal></entry>
      </row>

      <row>
       <entry><literal>windows_866_to_koi8_r</literal></entry>
       <entry><literal>WIN866</literal></entry>
       <entry><literal>KOI8</literal></entry>
      </row>

      <row>
       <entry><literal>windows_866_to_mic</literal></entry>
       <entry><literal>WIN866</literal></entry>
       <entry><literal>MULE_INTERNAL</literal></entry>
      </row>

      <row>
       <entry><literal>windows_866_to_utf8</literal></entry>
       <entry><literal>WIN866</literal></entry>
       <entry><literal>UTF8</literal></entry>
      </row>

      <row>
       <entry><literal>windows_866_to_windows_1251</literal></entry>
       <entry><literal>WIN866</literal></entry>
       <entry><literal>WIN</literal></entry>
      </row>

      <row>
       <entry><literal>windows_874_to_utf8</literal></entry>
       <entry><literal>WIN874</literal></entry>
       <entry><literal>UTF8</literal></entry>
      </row>

     </tbody>
    </tgroup>
   </table>

  </sect1>


  <sect1 id="functions-binarystring">
   <title>Binary String Functions and Operators</title>

   <indexterm zone="functions-binarystring">
    <primary>binary data</primary>
    <secondary>functions</secondary>
   </indexterm>

   <para>
    This section describes functions and operators for examining and
    manipulating values of type <type>bytea</type>.
   </para>

   <para>
    <acronym>SQL</acronym> defines some string functions with a
    special syntax where 
    certain key words rather than commas are used to separate the
    arguments.  Details are in
    <xref linkend="functions-binarystring-sql">.
    Some functions are also implemented using the regular syntax for
    function invocation.
    (See <xref linkend="functions-binarystring-other">.)
   </para>

   <table id="functions-binarystring-sql">
    <title><acronym>SQL</acronym> Binary String Functions and Operators</title>
    <tgroup cols="5">
     <thead>
      <row>
       <entry>Function</entry>
       <entry>Return Type</entry>
       <entry>Description</entry>
       <entry>Example</entry>
       <entry>Result</entry>  
      </row>
     </thead>

     <tbody>
      <row>
       <entry><literal><parameter>string</parameter> <literal>||</literal>
        <parameter>string</parameter></literal></entry>
       <entry> <type>bytea</type> </entry>
       <entry>
        String concatenation
        <indexterm>
         <primary>binary string</primary>
         <secondary>concatenation</secondary>
        </indexterm>
       </entry>
       <entry><literal>'\\\\Post'::bytea || '\\047gres\\000'::bytea</literal></entry>
       <entry><literal>\\Post'gres\000</literal></entry>
      </row>

      <row>
       <entry><literal><function>octet_length</function>(<parameter>string</parameter>)</literal></entry>
       <entry><type>integer</type></entry>
       <entry>Number of bytes in binary string</entry>
       <entry><literal>octet_length( 'jo\\000se'::bytea)</literal></entry>
       <entry><literal>5</literal></entry>
      </row>

      <row>
       <entry><literal><function>position</function>(<parameter>substring</parameter> in <parameter>string</parameter>)</literal></entry>
       <entry><type>integer</type></entry>
       <entry>Location of specified substring</entry>
      <entry><literal>position('\\000om'::bytea in 'Th\\000omas'::bytea)</literal></entry>
       <entry><literal>3</literal></entry>
      </row>

      <row>
       <entry><literal><function>substring</function>(<parameter>string</parameter> <optional>from <type>integer</type></optional> <optional>for <type>integer</type></optional>)</literal></entry>
       <entry><type>bytea</type></entry>
       <entry>
        Extract substring
        <indexterm>
         <primary>substring</primary>
        </indexterm>
       </entry>
       <entry><literal>substring('Th\\000omas'::bytea from 2 for 3)</literal></entry>
       <entry><literal>h\000o</literal></entry>
      </row>

      <row>
       <entry>
        <literal><function>trim</function>(<optional>both</optional>
        <parameter>bytes</parameter> from
        <parameter>string</parameter>)</literal>
       </entry>
       <entry><type>bytea</type></entry>
       <entry>
        Remove the longest string containing only the bytes in
        <parameter>bytes</parameter> from the start
        and end of <parameter>string</parameter>
       </entry>
       <entry><literal>trim('\\000'::bytea from '\\000Tom\\000'::bytea)</literal></entry>
       <entry><literal>Tom</literal></entry>
      </row>

      <row>
       <entry><function>get_byte</function>(<parameter>string</parameter>, <parameter>offset</parameter>)</entry>
       <entry><type>integer</type></entry>
       <entry>
        Extract byte from string
        <indexterm>
         <primary>get_byte</primary>
        </indexterm>
       </entry>
       <entry><literal>get_byte('Th\\000omas'::bytea, 4)</literal></entry>
       <entry><literal>109</literal></entry>
      </row>

      <row>
       <entry><function>set_byte</function>(<parameter>string</parameter>,
       <parameter>offset</parameter>, <parameter>newvalue</>)</entry>
       <entry><type>bytea</type></entry>
       <entry>
        Set byte in string
        <indexterm>
         <primary>set_byte</primary>
        </indexterm>
       </entry>
       <entry><literal>set_byte('Th\\000omas'::bytea, 4, 64)</literal></entry>
       <entry><literal>Th\000o@as</literal></entry>
      </row>

      <row>
       <entry><function>get_bit</function>(<parameter>string</parameter>, <parameter>offset</parameter>)</entry>
       <entry><type>integer</type></entry>
       <entry>
        Extract bit from string
        <indexterm>
         <primary>get_bit</primary>
        </indexterm>
       </entry>
       <entry><literal>get_bit('Th\\000omas'::bytea, 45)</literal></entry>
       <entry><literal>1</literal></entry>
      </row>

      <row>
       <entry><function>set_bit</function>(<parameter>string</parameter>,
       <parameter>offset</parameter>, <parameter>newvalue</>)</entry>
       <entry><type>bytea</type></entry>
       <entry>
        Set bit in string
        <indexterm>
         <primary>set_bit</primary>
        </indexterm>
       </entry>
       <entry><literal>set_bit('Th\\000omas'::bytea, 45, 0)</literal></entry>
       <entry><literal>Th\000omAs</literal></entry>
      </row>
     </tbody>
    </tgroup>
   </table>

   <para>
    Additional binary string manipulation functions are available and
    are listed in <xref linkend="functions-binarystring-other">.  Some
    of them are used internally to implement the
    <acronym>SQL</acronym>-standard string functions listed in <xref
    linkend="functions-binarystring-sql">.
   </para>

   <table id="functions-binarystring-other">
    <title>Other Binary String Functions</title>
    <tgroup cols="5">
     <thead>
      <row>
       <entry>Function</entry>
       <entry>Return Type</entry>
       <entry>Description</entry>
       <entry>Example</entry>
       <entry>Result</entry>
      </row>
     </thead>

     <tbody>
      <row>
       <entry><literal><function>btrim</function>(<parameter>string</parameter>
        <type>bytea</type>, <parameter>bytes</parameter> <type>bytea</type>)</literal></entry>
       <entry><type>bytea</type></entry>
       <entry>
        Remove the longest string consisting only of bytes
        in <parameter>bytes</parameter> from the start and end of
        <parameter>string</parameter>
      </entry>
      <entry><literal>btrim('\\000trim\\000'::bytea, '\\000'::bytea)</literal></entry>
      <entry><literal>trim</literal></entry>
     </row>

     <row>
      <entry><literal><function>length</function>(<parameter>string</parameter>)</literal></entry>
      <entry><type>integer</type></entry>
      <entry>
       Length of binary string
       <indexterm>
        <primary>binary string</primary>
        <secondary>length</secondary>
       </indexterm>
       <indexterm>
        <primary>length</primary>
        <secondary sortas="binary string">of a binary string</secondary>
        <see>binary strings, length</see>
       </indexterm>
      </entry>
      <entry><literal>length('jo\\000se'::bytea)</literal></entry>
      <entry><literal>5</literal></entry>
     </row>

     <row>
      <entry><literal><function>md5</function>(<parameter>string</parameter>)</literal></entry>
      <entry><type>text</type></entry>
      <entry>
       Calculates the MD5 hash of <parameter>string</parameter>,
       returning the result in hexadecimal
      </entry>
      <entry><literal>md5('Th\\000omas'::bytea)</literal></entry>
      <entry><literal>8ab2d3c9689aaf18 b4958c334c82d8b1</literal></entry>
     </row>

     <row>
      <entry>
       <literal><function>decode</function>(<parameter>string</parameter> <type>text</type>,
              <parameter>type</parameter> <type>text</type>)</literal>
      </entry>
      <entry><type>bytea</type></entry>
      <entry>
       Decode binary string from <parameter>string</parameter> previously 
       encoded with <literal>encode</>.  Parameter type is same as in <literal>encode</>.
      </entry>
      <entry><literal>decode('123\\000456', 'escape')</literal></entry>
      <entry><literal>123\000456</literal></entry>
     </row>       

     <row>
      <entry>
       <literal><function>encode</function>(<parameter>string</parameter> <type>bytea</type>,
              <parameter>type</parameter> <type>text</type>)</literal>
      </entry>
      <entry><type>text</type></entry>
      <entry>
       Encode binary string to <acronym>ASCII</acronym>-only representation.  Supported
       types are: <literal>base64</>, <literal>hex</>, <literal>escape</>.
      </entry>
      <entry><literal>encode('123\\000456'::bytea, 'escape')</literal></entry>
      <entry><literal>123\000456</literal></entry>
     </row>

    </tbody>
   </tgroup>
  </table>

 </sect1>


  <sect1 id="functions-bitstring">
   <title>Bit String Functions and Operators</title>

   <indexterm zone="functions-bitstring">
    <primary>bit strings</primary>
    <secondary>functions</secondary>
   </indexterm>

   <para>
    This section describes functions and operators for examining and
    manipulating bit strings, that is values of the types
    <type>bit</type> and <type>bit varying</type>.  Aside from the
    usual comparison operators, the operators
    shown in <xref linkend="functions-bit-string-op-table"> can be used.
    Bit string operands of <literal>&amp;</literal>, <literal>|</literal>,
    and <literal>#</literal> must be of equal length.  When bit
    shifting, the original length of the string is preserved, as shown
    in the examples.
   </para>

   <table id="functions-bit-string-op-table">
    <title>Bit String Operators</title>

    <tgroup cols="4">
     <thead>
      <row>
       <entry>Operator</entry>
       <entry>Description</entry>
       <entry>Example</entry>
       <entry>Result</entry>
      </row>
     </thead>

     <tbody>
      <row>
       <entry> <literal>||</literal> </entry>
       <entry>concatenation</entry>
       <entry><literal>B'10001' || B'011'</literal></entry>
       <entry><literal>10001011</literal></entry>
      </row>

      <row>
       <entry> <literal>&amp;</literal> </entry>
       <entry>bitwise AND</entry>
       <entry><literal>B'10001' &amp; B'01101'</literal></entry>
       <entry><literal>00001</literal></entry>
      </row>

      <row>
       <entry> <literal>|</literal> </entry>
       <entry>bitwise OR</entry>
       <entry><literal>B'10001' | B'01101'</literal></entry>
       <entry><literal>11101</literal></entry>
      </row>

      <row>
       <entry> <literal>#</literal> </entry>
       <entry>bitwise XOR</entry>
       <entry><literal>B'10001' # B'01101'</literal></entry>
       <entry><literal>11100</literal></entry>
      </row>

      <row>
       <entry> <literal>~</literal> </entry>
       <entry>bitwise NOT</entry>
       <entry><literal>~ B'10001'</literal></entry>
       <entry><literal>01110</literal></entry>
      </row>

      <row>
       <entry> <literal>&lt;&lt;</literal> </entry>
       <entry>bitwise shift left</entry>
       <entry><literal>B'10001' &lt;&lt; 3</literal></entry>
       <entry><literal>01000</literal></entry>
      </row>

      <row>
       <entry> <literal>&gt;&gt;</literal> </entry>
       <entry>bitwise shift right</entry>
       <entry><literal>B'10001' &gt;&gt; 2</literal></entry>
       <entry><literal>00100</literal></entry>
      </row>
     </tbody>
    </tgroup>
   </table>

   <para>
    The following <acronym>SQL</acronym>-standard functions work on bit
    strings as well as character strings:
    <literal><function>length</function></literal>,
    <literal><function>bit_length</function></literal>,
    <literal><function>octet_length</function></literal>,
    <literal><function>position</function></literal>,
    <literal><function>substring</function></literal>.
   </para>

   <para>
    In addition, it is possible to cast integral values to and from type
    <type>bit</>.
    Some examples:
<programlisting>
44::bit(10)                    <lineannotation>0000101100</lineannotation>
44::bit(3)                     <lineannotation>100</lineannotation>
cast(-44 as bit(12))           <lineannotation>111111010100</lineannotation>
'1110'::bit(4)::integer        <lineannotation>14</lineannotation>
</programlisting>
    Note that casting to just <quote>bit</> means casting to
    <literal>bit(1)</>, and so it will deliver only the least significant
    bit of the integer.
   </para>

    <note>
     <para>
      Prior to <productname>PostgreSQL</productname> 8.0, casting an
      integer to <type>bit(n)</> would copy the leftmost <literal>n</>
      bits of the integer, whereas now it copies the rightmost <literal>n</>
      bits.  Also, casting an integer to a bit string width wider than
      the integer itself will sign-extend on the left.
     </para>
    </note>

  </sect1>


 <sect1 id="functions-matching">
  <title>Pattern Matching</title>

  <indexterm zone="functions-matching">
   <primary>pattern matching</primary>
  </indexterm>

   <para>
    There are three separate approaches to pattern matching provided
    by <productname>PostgreSQL</productname>: the traditional
    <acronym>SQL</acronym> <function>LIKE</function> operator, the
    more recent <function>SIMILAR TO</function> operator (added in
    SQL:1999), and <acronym>POSIX</acronym>-style regular expressions.
    Additionally, a pattern matching function,
    <function>substring</function>, is available, using either
    <function>SIMILAR TO</function>-style or POSIX-style regular
    expressions.
   </para>

   <tip>
    <para>
     If you have pattern matching needs that go beyond this,
     consider writing a user-defined function in Perl or Tcl.
    </para>
   </tip>

  <sect2 id="functions-like">
   <title><function>LIKE</function></title>

   <indexterm zone="functions-like">
    <primary>LIKE</primary>
   </indexterm>

<synopsis>
<replaceable>string</replaceable> LIKE <replaceable>pattern</replaceable> <optional>ESCAPE <replaceable>escape-character</replaceable></optional>
<replaceable>string</replaceable> NOT LIKE <replaceable>pattern</replaceable> <optional>ESCAPE <replaceable>escape-character</replaceable></optional>
</synopsis>

    <para>
     Every <replaceable>pattern</replaceable> defines a set of strings.
     The <function>LIKE</function> expression returns true if the
     <replaceable>string</replaceable> is contained in the set of
     strings represented by <replaceable>pattern</replaceable>.  (As
     expected, the <function>NOT LIKE</function> expression returns
     false if <function>LIKE</function> returns true, and vice versa.
     An equivalent expression is
     <literal>NOT (<replaceable>string</replaceable> LIKE
      <replaceable>pattern</replaceable>)</literal>.)
    </para>

    <para>
     If <replaceable>pattern</replaceable> does not contain percent
     signs or underscore, then the pattern only represents the string
     itself; in that case <function>LIKE</function> acts like the
     equals operator.  An underscore (<literal>_</literal>) in
     <replaceable>pattern</replaceable> stands for (matches) any single
     character; a percent sign (<literal>%</literal>) matches any string
     of zero or more characters.
    </para>

   <para>
    Some examples:
<programlisting>
'abc' LIKE 'abc'    <lineannotation>true</lineannotation>
'abc' LIKE 'a%'     <lineannotation>true</lineannotation>
'abc' LIKE '_b_'    <lineannotation>true</lineannotation>
'abc' LIKE 'c'      <lineannotation>false</lineannotation>
</programlisting>
   </para>
   
   <para>
    <function>LIKE</function> pattern matches always cover the entire
    string.  To match a sequence anywhere within a string, the
    pattern must therefore start and end with a percent sign.
   </para>

   <para>
    To match a literal underscore or percent sign without matching
    other characters, the respective character in
    <replaceable>pattern</replaceable> must be 
    preceded by the escape character.  The default escape
    character is the backslash but a different one may be selected by
    using the <literal>ESCAPE</literal> clause.  To match the escape
    character itself, write two escape characters.
   </para>

   <para>
    Note that the backslash already has a special meaning in string
    literals, so to write a pattern constant that contains a backslash
    you must write two backslashes in an SQL statement.  Thus, writing a pattern
    that actually matches a literal backslash means writing four backslashes
    in the statement.  You can avoid this by selecting a different escape
    character with <literal>ESCAPE</literal>; then a backslash is not special
    to <function>LIKE</function> anymore. (But it is still special to the string
    literal parser, so you still need two of them.)
   </para>

   <para>
    It's also possible to select no escape character by writing
    <literal>ESCAPE ''</literal>.  This effectively disables the
    escape mechanism, which makes it impossible to turn off the
    special meaning of underscore and percent signs in the pattern.
   </para>

   <para>
    The key word <token>ILIKE</token> can be used instead of
    <token>LIKE</token> to make the match case-insensitive according
    to the active locale.  This is not in the <acronym>SQL</acronym> standard but is a
    <productname>PostgreSQL</productname> extension.
   </para>

   <para>
    The operator <literal>~~</literal> is equivalent to
    <function>LIKE</function>, and <literal>~~*</literal> corresponds to
    <function>ILIKE</function>.  There are also
    <literal>!~~</literal> and <literal>!~~*</literal> operators that
    represent <function>NOT LIKE</function> and <function>NOT
    ILIKE</function>, respectively.  All of these operators are
    <productname>PostgreSQL</productname>-specific.
   </para>
  </sect2>


  <sect2 id="functions-similarto-regexp">
   <title><function>SIMILAR TO</function> Regular Expressions</title>

   <indexterm zone="functions-similarto-regexp">
    <primary>regular expression</primary>
    <!-- <seealso>pattern matching</seealso> breaks index build -->
   </indexterm>

   <indexterm>
    <primary>SIMILAR TO</primary>
   </indexterm>

   <indexterm>
    <primary>substring</primary>
   </indexterm>

<synopsis>
<replaceable>string</replaceable> SIMILAR TO <replaceable>pattern</replaceable> <optional>ESCAPE <replaceable>escape-character</replaceable></optional>
<replaceable>string</replaceable> NOT SIMILAR TO <replaceable>pattern</replaceable> <optional>ESCAPE <replaceable>escape-character</replaceable></optional>
</synopsis>

    <para>
     The <function>SIMILAR TO</function> operator returns true or
     false depending on whether its pattern matches the given string.
     It is much like <function>LIKE</function>, except that it
     interprets the pattern using the SQL standard's definition of a
     regular expression.  SQL regular expressions are a curious cross
     between <function>LIKE</function> notation and common regular
     expression notation.
    </para>

    <para>
     Like <function>LIKE</function>, the  <function>SIMILAR TO</function>
     operator succeeds only if its pattern matches the entire string;
     this is unlike common regular expression practice, wherein the pattern
     may match any part of the string.
     Also like
     <function>LIKE</function>, <function>SIMILAR TO</function> uses
     <literal>_</> and <literal>%</> as wildcard characters denoting
     any single character and any string, respectively (these are
     comparable to <literal>.</> and <literal>.*</> in POSIX regular
     expressions).
    </para>

    <para>
     In addition to these facilities borrowed from <function>LIKE</function>,
     <function>SIMILAR TO</function> supports these pattern-matching
     metacharacters borrowed from POSIX regular expressions:

    <itemizedlist>
     <listitem>
      <para>
       <literal>|</literal> denotes alternation (either of two alternatives).
      </para>
     </listitem>
     <listitem>
      <para>
       <literal>*</literal> denotes repetition of the previous item zero
       or more times.
      </para>
     </listitem>
     <listitem>
      <para>
       <literal>+</literal> denotes repetition of the previous item one
       or more times.
      </para>
     </listitem>
     <listitem>
      <para>
       Parentheses <literal>()</literal> may be used to group items into
       a single logical item.
      </para>
     </listitem>
     <listitem>
      <para>
       A bracket expression <literal>[...]</literal> specifies a character
       class, just as in POSIX regular expressions.
      </para>
     </listitem>
    </itemizedlist>

     Notice that bounded repetition (<literal>?</> and <literal>{...}</>)
     are not provided, though they exist in POSIX.  Also, the dot (<literal>.</>)
     is not a metacharacter.
    </para>

    <para>
     As with <function>LIKE</>, a backslash disables the special meaning
     of any of these metacharacters; or a different escape character can
     be specified with <literal>ESCAPE</>.
    </para>

   <para>
    Some examples:
<programlisting>
'abc' SIMILAR TO 'abc'      <lineannotation>true</lineannotation>
'abc' SIMILAR TO 'a'        <lineannotation>false</lineannotation>
'abc' SIMILAR TO '%(b|d)%'  <lineannotation>true</lineannotation>
'abc' SIMILAR TO '(b|c)%'   <lineannotation>false</lineannotation>
</programlisting>
   </para>

    <para>
     The <function>substring</> function with three parameters,
     <function>substring(<replaceable>string</replaceable> from
     <replaceable>pattern</replaceable> for
     <replaceable>escape-character</replaceable>)</function>, provides
     extraction of a substring that matches an SQL
     regular expression pattern.  As with <literal>SIMILAR TO</>, the
     specified pattern must match to the entire data string, else the
     function fails and returns null.  To indicate the part of the
     pattern that should be returned on success, the pattern must contain
     two occurrences of the escape character followed by a double quote
     (<literal>"</>).  The text matching the portion of the pattern
     between these markers is returned.
    </para>

   <para>
    Some examples:
<programlisting>
substring('foobar' from '%#"o_b#"%' for '#')   <lineannotation>oob</lineannotation>
substring('foobar' from '#"o_b#"%' for '#')    <lineannotation>NULL</lineannotation>
</programlisting>
   </para>
  </sect2>

  <sect2 id="functions-posix-regexp">
   <title><acronym>POSIX</acronym> Regular Expressions</title>

   <indexterm zone="functions-posix-regexp">
    <primary>regular expression</primary>
    <seealso>pattern matching</seealso>
   </indexterm>

   <para>
    <xref linkend="functions-posix-table"> lists the available
    operators for pattern matching using POSIX regular expressions.
   </para>

   <table id="functions-posix-table">
    <title>Regular Expression Match Operators</title>

    <tgroup cols="3">
     <thead>
      <row>
       <entry>Operator</entry>
       <entry>Description</entry>
       <entry>Example</entry>
      </row>
     </thead>

      <tbody>
       <row>
        <entry> <literal>~</literal> </entry>
        <entry>Matches regular expression, case sensitive</entry>
        <entry><literal>'thomas' ~ '.*thomas.*'</literal></entry>
       </row>

       <row>
        <entry> <literal>~*</literal> </entry>
        <entry>Matches regular expression, case insensitive</entry>
        <entry><literal>'thomas' ~* '.*Thomas.*'</literal></entry>
       </row>

       <row>
        <entry> <literal>!~</literal> </entry>
        <entry>Does not match regular expression, case sensitive</entry>
        <entry><literal>'thomas' !~ '.*Thomas.*'</literal></entry>
       </row>

       <row>
        <entry> <literal>!~*</literal> </entry>
        <entry>Does not match regular expression, case insensitive</entry>
        <entry><literal>'thomas' !~* '.*vadim.*'</literal></entry>
       </row>
      </tbody>
     </tgroup>
    </table>

    <para>
     <acronym>POSIX</acronym> regular expressions provide a more
     powerful means for 
     pattern matching than the <function>LIKE</function> and
     <function>SIMILAR TO</> operators.
     Many Unix tools such as <command>egrep</command>,
     <command>sed</command>, or <command>awk</command> use a pattern
     matching language that is similar to the one described here.
    </para>

    <para>
     A regular expression is a character sequence that is an
     abbreviated definition of a set of strings (a <firstterm>regular
      set</firstterm>).  A string is said to match a regular expression
     if it is a member of the regular set described by the regular
     expression.  As with <function>LIKE</function>, pattern characters
     match string characters exactly unless they are special characters
     in the regular expression language &mdash; but regular expressions use
     different special characters than <function>LIKE</function> does.
     Unlike <function>LIKE</function> patterns, a
     regular expression is allowed to match anywhere within a string, unless
     the regular expression is explicitly anchored to the beginning or
     end of the string.
    </para>

   <para>
    Some examples:
<programlisting>
'abc' ~ 'abc'    <lineannotation>true</lineannotation>
'abc' ~ '^a'     <lineannotation>true</lineannotation>
'abc' ~ '(b|d)'  <lineannotation>true</lineannotation>
'abc' ~ '^(b|c)' <lineannotation>false</lineannotation>
</programlisting>
   </para>

    <para>
     The <function>substring</> function with two parameters,
     <function>substring(<replaceable>string</replaceable> from
     <replaceable>pattern</replaceable>)</function>, provides extraction of a substring
     that matches a POSIX regular expression pattern.  It returns null if
     there is no match, otherwise the portion of the text that matched the
     pattern.  But if the pattern contains any parentheses, the portion
     of the text that matched the first parenthesized subexpression (the
     one whose left parenthesis comes first) is
     returned.  You can put parentheses around the whole expression
     if you want to use parentheses within it without triggering this
     exception.  If you need parentheses in the pattern before the
     subexpression you want to extract, see the non-capturing parentheses
     described below.
    </para>

   <para>
    Some examples:
<programlisting>
substring('foobar' from 'o.b')     <lineannotation>oob</lineannotation>
substring('foobar' from 'o(.)b')   <lineannotation>o</lineannotation>
</programlisting>
   </para>

   <para>
    <productname>PostgreSQL</productname>'s regular expressions are implemented
    using a package written by Henry Spencer.  Much of
    the description of regular expressions below is copied verbatim from his
    manual entry.
   </para>

<!-- derived from the re_syntax.n man page -->

   <sect3 id="posix-syntax-details">
    <title>Regular Expression Details</title>

   <para>
    Regular expressions (<acronym>RE</acronym>s), as defined in
    <acronym>POSIX</acronym> 1003.2, come in two forms:
    <firstterm>extended</> <acronym>RE</acronym>s or <acronym>ERE</>s
    (roughly those of <command>egrep</command>), and
    <firstterm>basic</> <acronym>RE</acronym>s or <acronym>BRE</>s
    (roughly those of <command>ed</command>).
    <productname>PostgreSQL</productname> supports both forms, and
    also implements some extensions
    that are not in the POSIX standard, but have become widely used anyway
    due to their availability in programming languages such as Perl and Tcl.
    <acronym>RE</acronym>s using these non-POSIX extensions are called
    <firstterm>advanced</> <acronym>RE</acronym>s or <acronym>ARE</>s
    in this documentation.  AREs are almost an exact superset of EREs,
    but BREs have several notational incompatibilities (as well as being
    much more limited).
    We first describe the ARE and ERE forms, noting features that apply
    only to AREs, and then describe how BREs differ.
   </para>

   <note>
    <para>
     The form of regular expressions accepted by
     <productname>PostgreSQL</> can be chosen by setting the <xref
     linkend="guc-regex-flavor"> run-time parameter.  The usual
     setting is <literal>advanced</>, but one might choose
     <literal>extended</> for maximum backwards compatibility with
     pre-7.4 releases of <productname>PostgreSQL</>.
    </para>
   </note>

   <para>
    A regular expression is defined as one or more
    <firstterm>branches</firstterm>, separated by
    <literal>|</literal>.  It matches anything that matches one of the
    branches.
   </para>

   <para>
    A branch is zero or more <firstterm>quantified atoms</> or
    <firstterm>constraints</>, concatenated.
    It matches a match for the first, followed by a match for the second, etc;
    an empty branch matches the empty string.
   </para>

   <para>
    A quantified atom is an <firstterm>atom</> possibly followed
    by a single <firstterm>quantifier</>.
    Without a quantifier, it matches a match for the atom.
    With a quantifier, it can match some number of matches of the atom.
    An <firstterm>atom</firstterm> can be any of the possibilities
    shown in <xref linkend="posix-atoms-table">.
    The possible quantifiers and their meanings are shown in
    <xref linkend="posix-quantifiers-table">.
   </para>

   <para>
    A <firstterm>constraint</> matches an empty string, but matches only when
    specific conditions are met.  A constraint can be used where an atom
    could be used, except it may not be followed by a quantifier.
    The simple constraints are shown in
    <xref linkend="posix-constraints-table">;
    some more constraints are described later.
   </para>


   <table id="posix-atoms-table">
    <title>Regular Expression Atoms</title>

    <tgroup cols="2">
     <thead>
      <row>
       <entry>Atom</entry>
       <entry>Description</entry>
      </row>
     </thead>

      <tbody>
       <row>
       <entry> <literal>(</><replaceable>re</><literal>)</> </entry>
       <entry> (where <replaceable>re</> is any regular expression)
       matches a match for
       <replaceable>re</>, with the match noted for possible reporting </entry>
       </row>

       <row>
       <entry> <literal>(?:</><replaceable>re</><literal>)</> </entry>
       <entry> as above, but the match is not noted for reporting
       (a <quote>non-capturing</> set of parentheses)
       (AREs only) </entry>
       </row>

       <row>
       <entry> <literal>.</> </entry>
       <entry> matches any single character </entry>
       </row>

       <row>
       <entry> <literal>[</><replaceable>chars</><literal>]</> </entry>
       <entry> a <firstterm>bracket expression</>,
       matching any one of the <replaceable>chars</> (see
       <xref linkend="posix-bracket-expressions"> for more detail) </entry>
       </row>

       <row>
       <entry> <literal>\</><replaceable>k</> </entry>
       <entry> (where <replaceable>k</> is a non-alphanumeric character)
       matches that character taken as an ordinary character,
       e.g. <literal>\\</> matches a backslash character </entry>
       </row>

       <row>
       <entry> <literal>\</><replaceable>c</> </entry>
       <entry> where <replaceable>c</> is alphanumeric
       (possibly followed by other characters)
       is an <firstterm>escape</>, see <xref linkend="posix-escape-sequences">
       (AREs only; in EREs and BREs, this matches <replaceable>c</>) </entry>
       </row>

       <row>
       <entry> <literal>{</> </entry>
       <entry> when followed by a character other than a digit,
       matches the left-brace character <literal>{</>;
       when followed by a digit, it is the beginning of a
       <replaceable>bound</> (see below) </entry>
       </row>

       <row>
       <entry> <replaceable>x</> </entry>
       <entry> where <replaceable>x</> is a single character with no other
       significance, matches that character </entry>
       </row>
      </tbody>
     </tgroup>
    </table>

   <para>
    An RE may not end with <literal>\</>.
   </para>

   <note>
    <para>
     Remember that the backslash (<literal>\</literal>) already has a special
     meaning in <productname>PostgreSQL</> string literals.
     To write a pattern constant that contains a backslash,
     you must write two backslashes in the statement.
    </para>
   </note>

   <table id="posix-quantifiers-table">
    <title>Regular Expression Quantifiers</title>

    <tgroup cols="2">
     <thead>
      <row>
       <entry>Quantifier</entry>
       <entry>Matches</entry>
      </row>
     </thead>

      <tbody>
       <row>
       <entry> <literal>*</> </entry>
       <entry> a sequence of 0 or more matches of the atom </entry>
       </row>

       <row>
       <entry> <literal>+</> </entry>
       <entry> a sequence of 1 or more matches of the atom </entry>
       </row>

       <row>
       <entry> <literal>?</> </entry>
       <entry> a sequence of 0 or 1 matches of the atom </entry>
       </row>

       <row>
       <entry> <literal>{</><replaceable>m</><literal>}</> </entry>
       <entry> a sequence of exactly <replaceable>m</> matches of the atom </entry>
       </row>

       <row>
       <entry> <literal>{</><replaceable>m</><literal>,}</> </entry>
       <entry> a sequence of <replaceable>m</> or more matches of the atom </entry>
       </row>

       <row>
       <entry>
       <literal>{</><replaceable>m</><literal>,</><replaceable>n</><literal>}</> </entry>
       <entry> a sequence of <replaceable>m</> through <replaceable>n</>
       (inclusive) matches of the atom; <replaceable>m</> may not exceed
       <replaceable>n</> </entry>
       </row>

       <row>
       <entry> <literal>*?</> </entry>
       <entry> non-greedy version of <literal>*</> </entry>
       </row>

       <row>
       <entry> <literal>+?</> </entry>
       <entry> non-greedy version of <literal>+</> </entry>
       </row>

       <row>
       <entry> <literal>??</> </entry>
       <entry> non-greedy version of <literal>?</> </entry>
       </row>

       <row>
       <entry> <literal>{</><replaceable>m</><literal>}?</> </entry>
       <entry> non-greedy version of <literal>{</><replaceable>m</><literal>}</> </entry>
       </row>

       <row>
       <entry> <literal>{</><replaceable>m</><literal>,}?</> </entry>
       <entry> non-greedy version of <literal>{</><replaceable>m</><literal>,}</> </entry>
       </row>

       <row>
       <entry>
       <literal>{</><replaceable>m</><literal>,</><replaceable>n</><literal>}?</> </entry>
       <entry> non-greedy version of <literal>{</><replaceable>m</><literal>,</><replaceable>n</><literal>}</> </entry>
       </row>
      </tbody>
     </tgroup>
    </table>

   <para>
    The forms using <literal>{</><replaceable>...</><literal>}</>
    are known as <firstterm>bounds</>.
    The numbers <replaceable>m</> and <replaceable>n</> within a bound are
    unsigned decimal integers with permissible values from 0 to 255 inclusive.
   </para>

    <para>
     <firstterm>Non-greedy</> quantifiers (available in AREs only) match the
     same possibilities as their corresponding normal (<firstterm>greedy</>)
     counterparts, but prefer the smallest number rather than the largest
     number of matches.
     See <xref linkend="posix-matching-rules"> for more detail.
   </para>

   <note>
    <para>
     A quantifier cannot immediately follow another quantifier.
     A quantifier cannot
     begin an expression or subexpression or follow
     <literal>^</literal> or <literal>|</literal>.
    </para>
   </note>

   <table id="posix-constraints-table">
    <title>Regular Expression Constraints</title>

    <tgroup cols="2">
     <thead>
      <row>
       <entry>Constraint</entry>
       <entry>Description</entry>
      </row>
     </thead>

      <tbody>
       <row>
       <entry> <literal>^</> </entry>
       <entry> matches at the beginning of the string </entry>
       </row>

       <row>
       <entry> <literal>$</> </entry>
       <entry> matches at the end of the string </entry>
       </row>

       <row>
       <entry> <literal>(?=</><replaceable>re</><literal>)</> </entry>
       <entry> <firstterm>positive lookahead</> matches at any point
       where a substring matching <replaceable>re</> begins
       (AREs only) </entry>
       </row>

       <row>
       <entry> <literal>(?!</><replaceable>re</><literal>)</> </entry>
       <entry> <firstterm>negative lookahead</> matches at any point
       where no substring matching <replaceable>re</> begins
       (AREs only) </entry>
       </row>
      </tbody>
     </tgroup>
    </table>

   <para>
    Lookahead constraints may not contain <firstterm>back references</>
    (see <xref linkend="posix-escape-sequences">),
    and all parentheses within them are considered non-capturing.
   </para>
   </sect3>

   <sect3 id="posix-bracket-expressions">
    <title>Bracket Expressions</title>

   <para>
    A <firstterm>bracket expression</firstterm> is a list of
    characters enclosed in <literal>[]</literal>.  It normally matches
    any single character from the list (but see below).  If the list
    begins with <literal>^</literal>, it matches any single character
    <emphasis>not</> from the rest of the list.
    If two characters
    in the list are separated by <literal>-</literal>, this is
    shorthand for the full range of characters between those two
    (inclusive) in the collating sequence,
    e.g. <literal>[0-9]</literal> in <acronym>ASCII</acronym> matches
    any decimal digit.  It is illegal for two ranges to share an
    endpoint, e.g.  <literal>a-c-e</literal>.  Ranges are very
    collating-sequence-dependent, so portable programs should avoid
    relying on them.
   </para>

   <para>
    To include a literal <literal>]</literal> in the list, make it the
    first character (following a possible <literal>^</literal>).  To
    include a literal <literal>-</literal>, make it the first or last
    character, or the second endpoint of a range.  To use a literal
    <literal>-</literal> as the first endpoint of a range, enclose it
    in <literal>[.</literal> and <literal>.]</literal> to make it a
    collating element (see below).  With the exception of these characters,
    some combinations using <literal>[</literal>
    (see next paragraphs), and escapes (AREs only), all other special
    characters lose their special significance within a bracket expression.
    In particular, <literal>\</literal> is not special when following
    ERE or BRE rules, though it is special (as introducing an escape)
    in AREs.
   </para>

   <para>
    Within a bracket expression, a collating element (a character, a
    multiple-character sequence that collates as if it were a single
    character, or a collating-sequence name for either) enclosed in
    <literal>[.</literal> and <literal>.]</literal> stands for the
    sequence of characters of that collating element.  The sequence is
    a single element of the bracket expression's list.  A bracket
    expression containing a multiple-character collating element can thus
    match more than one character, e.g. if the collating sequence
    includes a <literal>ch</literal> collating element, then the RE
    <literal>[[.ch.]]*c</literal> matches the first five characters of
    <literal>chchcc</literal>.
   </para>

   <note>
    <para>
     <productname>PostgreSQL</> currently has no multi-character collating
     elements. This information describes possible future behavior.
    </para>
   </note>

   <para>
    Within a bracket expression, a collating element enclosed in
    <literal>[=</literal> and <literal>=]</literal> is an equivalence
    class, standing for the sequences of characters of all collating
    elements equivalent to that one, including itself.  (If there are
    no other equivalent collating elements, the treatment is as if the
    enclosing delimiters were <literal>[.</literal> and
    <literal>.]</literal>.)  For example, if <literal>o</literal> and
    <literal>^</literal> are the members of an equivalence class, then
    <literal>[[=o=]]</literal>, <literal>[[=^=]]</literal>, and
    <literal>[o^]</literal> are all synonymous.  An equivalence class
    may not be an endpoint of a range.
   </para>

   <para>
    Within a bracket expression, the name of a character class
    enclosed in <literal>[:</literal> and <literal>:]</literal> stands
    for the list of all characters belonging to that class.  Standard
    character class names are: <literal>alnum</literal>,
    <literal>alpha</literal>, <literal>blank</literal>,
    <literal>cntrl</literal>, <literal>digit</literal>,
    <literal>graph</literal>, <literal>lower</literal>,
    <literal>print</literal>, <literal>punct</literal>,
    <literal>space</literal>, <literal>upper</literal>,
    <literal>xdigit</literal>.  These stand for the character classes
    defined in
    <citerefentry><refentrytitle>ctype</refentrytitle><manvolnum>3</manvolnum></citerefentry>.
    A locale may provide others.  A character class may not be used as
    an endpoint of a range.
   </para>

   <para>
    There are two special cases of bracket expressions:  the bracket
    expressions <literal>[[:&lt;:]]</literal> and
    <literal>[[:&gt;:]]</literal> are constraints,
    matching empty strings at the beginning
    and end of a word respectively.  A word is defined as a sequence
    of word characters that is neither preceded nor followed by word
    characters.  A word character is an <literal>alnum</> character (as
    defined by
    <citerefentry><refentrytitle>ctype</refentrytitle><manvolnum>3</manvolnum></citerefentry>)
    or an underscore.  This is an extension, compatible with but not
    specified by <acronym>POSIX</acronym> 1003.2, and should be used with
    caution in software intended to be portable to other systems.
    The constraint escapes described below are usually preferable (they
    are no more standard, but are certainly easier to type).
   </para>
   </sect3>

   <sect3 id="posix-escape-sequences">
    <title>Regular Expression Escapes</title>

   <para>
    <firstterm>Escapes</> are special sequences beginning with <literal>\</>
    followed by an alphanumeric character. Escapes come in several varieties:
    character entry, class shorthands, constraint escapes, and back references.
    A <literal>\</> followed by an alphanumeric character but not constituting
    a valid escape is illegal in AREs.
    In EREs, there are no escapes: outside a bracket expression,
    a <literal>\</> followed by an alphanumeric character merely stands for
    that character as an ordinary character, and inside a bracket expression,
    <literal>\</> is an ordinary character.
    (The latter is the one actual incompatibility between EREs and AREs.)
   </para>

   <para>
    <firstterm>Character-entry escapes</> exist to make it easier to specify
    non-printing and otherwise inconvenient characters in REs.  They are
    shown in <xref linkend="posix-character-entry-escapes-table">.
   </para>

   <para>
    <firstterm>Class-shorthand escapes</> provide shorthands for certain
    commonly-used character classes.  They are
    shown in <xref linkend="posix-class-shorthand-escapes-table">.
   </para>

   <para>
    A <firstterm>constraint escape</> is a constraint,
    matching the empty string if specific conditions are met,
    written as an escape.  They are
    shown in <xref linkend="posix-constraint-escapes-table">.
   </para>

   <para>
    A <firstterm>back reference</> (<literal>\</><replaceable>n</>) matches the
    same string matched by the previous parenthesized subexpression specified
    by the number <replaceable>n</>
    (see <xref linkend="posix-constraint-backref-table">).  For example,
    <literal>([bc])\1</> matches <literal>bb</> or <literal>cc</>
    but not <literal>bc</> or <literal>cb</>.
    The subexpression must entirely precede the back reference in the RE.
    Subexpressions are numbered in the order of their leading parentheses.
    Non-capturing parentheses do not define subexpressions.
   </para>

   <note>
    <para>
     Keep in mind that an escape's leading <literal>\</> will need to be
     doubled when entering the pattern as an SQL string constant.  For example:
<programlisting>
'123' ~ '^\\d{3}' <lineannotation>true</lineannotation>
</programlisting>
    </para>
   </note>

   <table id="posix-character-entry-escapes-table">
    <title>Regular Expression Character-Entry Escapes</title>

    <tgroup cols="2">
     <thead>
      <row>
       <entry>Escape</entry>
       <entry>Description</entry>
      </row>
     </thead>

      <tbody>
       <row>
       <entry> <literal>\a</> </entry>
       <entry> alert (bell) character, as in C </entry>
       </row>

       <row>
       <entry> <literal>\b</> </entry>
       <entry> backspace, as in C </entry>
       </row>

       <row>
       <entry> <literal>\B</> </entry>
       <entry> synonym for <literal>\</> to help reduce the need for backslash
       doubling </entry>
       </row>

       <row>
       <entry> <literal>\c</><replaceable>X</> </entry>
       <entry> (where <replaceable>X</> is any character) the character whose
       low-order 5 bits are the same as those of
       <replaceable>X</>, and whose other bits are all zero </entry>
       </row>

       <row>
       <entry> <literal>\e</> </entry>
       <entry> the character whose collating-sequence name
       is <literal>ESC</>,
       or failing that, the character with octal value 033 </entry>
       </row>

       <row>
       <entry> <literal>\f</> </entry>
       <entry> form feed, as in C </entry>
       </row>

       <row>
       <entry> <literal>\n</> </entry>
       <entry> newline, as in C </entry>
       </row>

       <row>
       <entry> <literal>\r</> </entry>
       <entry> carriage return, as in C </entry>
       </row>

       <row>
       <entry> <literal>\t</> </entry>
       <entry> horizontal tab, as in C </entry>
       </row>

       <row>
       <entry> <literal>\u</><replaceable>wxyz</> </entry>
       <entry> (where <replaceable>wxyz</> is exactly four hexadecimal digits)
       the UTF16 (Unicode, 16-bit) character <literal>U+</><replaceable>wxyz</>
       in the local byte ordering </entry>
       </row>

       <row>
       <entry> <literal>\U</><replaceable>stuvwxyz</> </entry>
       <entry> (where <replaceable>stuvwxyz</> is exactly eight hexadecimal
       digits)
       reserved for a somewhat-hypothetical Unicode extension to 32 bits
       </entry> 
       </row>

       <row>
       <entry> <literal>\v</> </entry>
       <entry> vertical tab, as in C </entry>
       </row>

       <row>
       <entry> <literal>\x</><replaceable>hhh</> </entry>
       <entry> (where <replaceable>hhh</> is any sequence of hexadecimal
       digits)
       the character whose hexadecimal value is
       <literal>0x</><replaceable>hhh</>
       (a single character no matter how many hexadecimal digits are used)
       </entry>
       </row>

       <row>
       <entry> <literal>\0</> </entry>
       <entry> the character whose value is <literal>0</> </entry>
       </row>

       <row>
       <entry> <literal>\</><replaceable>xy</> </entry>
       <entry> (where <replaceable>xy</> is exactly two octal digits,
       and is not a <firstterm>back reference</>)
       the character whose octal value is
       <literal>0</><replaceable>xy</> </entry>
       </row>

       <row>
       <entry> <literal>\</><replaceable>xyz</> </entry>
       <entry> (where <replaceable>xyz</> is exactly three octal digits,
       and is not a <firstterm>back reference</>)
       the character whose octal value is
       <literal>0</><replaceable>xyz</> </entry>
       </row>
      </tbody>
     </tgroup>
    </table>

   <para>
    Hexadecimal digits are <literal>0</>-<literal>9</>,
    <literal>a</>-<literal>f</>, and <literal>A</>-<literal>F</>.
    Octal digits are <literal>0</>-<literal>7</>.
   </para>

   <para>
    The character-entry escapes are always taken as ordinary characters.
    For example, <literal>\135</> is <literal>]</> in ASCII, but
    <literal>\135</> does not terminate a bracket expression.
   </para>

   <table id="posix-class-shorthand-escapes-table">
    <title>Regular Expression Class-Shorthand Escapes</title>

    <tgroup cols="2">
     <thead>
      <row>
       <entry>Escape</entry>
       <entry>Description</entry>
      </row>
     </thead>

      <tbody>
       <row>
       <entry> <literal>\d</> </entry>
       <entry> <literal>[[:digit:]]</> </entry>
       </row>

       <row>
       <entry> <literal>\s</> </entry>
       <entry> <literal>[[:space:]]</> </entry>
       </row>

       <row>
       <entry> <literal>\w</> </entry>
       <entry> <literal>[[:alnum:]_]</>
       (note underscore is included) </entry>
       </row>

       <row>
       <entry> <literal>\D</> </entry>
       <entry> <literal>[^[:digit:]]</> </entry>
       </row>

       <row>
       <entry> <literal>\S</> </entry>
       <entry> <literal>[^[:space:]]</> </entry>
       </row>

       <row>
       <entry> <literal>\W</> </entry>
       <entry> <literal>[^[:alnum:]_]</>
       (note underscore is included) </entry>
       </row>
      </tbody>
     </tgroup>
    </table>

   <para>
    Within bracket expressions, <literal>\d</>, <literal>\s</>,
    and <literal>\w</> lose their outer brackets,
    and <literal>\D</>, <literal>\S</>, and <literal>\W</> are illegal.
    (So, for example, <literal>[a-c\d]</> is equivalent to
    <literal>[a-c[:digit:]]</>.
    Also, <literal>[a-c\D]</>, which is equivalent to
    <literal>[a-c^[:digit:]]</>, is illegal.)
   </para>

   <table id="posix-constraint-escapes-table">
    <title>Regular Expression Constraint Escapes</title>

    <tgroup cols="2">
     <thead>
      <row>
       <entry>Escape</entry>
       <entry>Description</entry>
      </row>
     </thead>

      <tbody>
       <row>
       <entry> <literal>\A</> </entry>
       <entry> matches only at the beginning of the string
       (see <xref linkend="posix-matching-rules"> for how this differs from
       <literal>^</>) </entry>
       </row>

       <row>
       <entry> <literal>\m</> </entry>
       <entry> matches only at the beginning of a word </entry>
       </row>

       <row>
       <entry> <literal>\M</> </entry>
       <entry> matches only at the end of a word </entry>
       </row>

       <row>
       <entry> <literal>\y</> </entry>
       <entry> matches only at the beginning or end of a word </entry>
       </row>

       <row>
       <entry> <literal>\Y</> </entry>
       <entry> matches only at a point that is not the beginning or end of a
       word </entry>
       </row>

       <row>
       <entry> <literal>\Z</> </entry>
       <entry> matches only at the end of the string
       (see <xref linkend="posix-matching-rules"> for how this differs from
       <literal>$</>) </entry>
       </row>
      </tbody>
     </tgroup>
    </table>

   <para>
    A word is defined as in the specification of
    <literal>[[:&lt;:]]</> and <literal>[[:&gt;:]]</> above.
    Constraint escapes are illegal within bracket expressions.
   </para>

   <table id="posix-constraint-backref-table">
    <title>Regular Expression Back References</title>

    <tgroup cols="2">
     <thead>
      <row>
       <entry>Escape</entry>
       <entry>Description</entry>
      </row>
     </thead>

      <tbody>
       <row>
       <entry> <literal>\</><replaceable>m</> </entry>
       <entry> (where <replaceable>m</> is a nonzero digit)
       a back reference to the <replaceable>m</>'th subexpression </entry>
       </row>

       <row>
       <entry> <literal>\</><replaceable>mnn</> </entry>
       <entry> (where <replaceable>m</> is a nonzero digit, and
       <replaceable>nn</> is some more digits, and the decimal value
       <replaceable>mnn</> is not greater than the number of closing capturing
       parentheses seen so far) 
       a back reference to the <replaceable>mnn</>'th subexpression </entry>
       </row>
      </tbody>
     </tgroup>
    </table>

   <note>
    <para>
     There is an inherent historical ambiguity between octal character-entry 
     escapes and back references, which is resolved by heuristics,
     as hinted at above.
     A leading zero always indicates an octal escape.
     A single non-zero digit, not followed by another digit,
     is always taken as a back reference.
     A multi-digit sequence not starting with a zero is taken as a back 
     reference if it comes after a suitable subexpression
     (i.e. the number is in the legal range for a back reference),
     and otherwise is taken as octal.
    </para>
   </note>
   </sect3>

   <sect3 id="posix-metasyntax">
    <title>Regular Expression Metasyntax</title>

   <para>
    In addition to the main syntax described above, there are some special
    forms and miscellaneous syntactic facilities available.
   </para>

   <para>
    Normally the flavor of RE being used is determined by
    <varname>regex_flavor</>.
    However, this can be overridden by a <firstterm>director</> prefix.
    If an RE begins with <literal>***:</>,
    the rest of the RE is taken as an ARE regardless of
    <varname>regex_flavor</>.
    If an RE begins with <literal>***=</>,
    the rest of the RE is taken to be a literal string,
    with all characters considered ordinary characters.
   </para>

   <para>
    An ARE may begin with <firstterm>embedded options</>:
    a sequence <literal>(?</><replaceable>xyz</><literal>)</>
    (where <replaceable>xyz</> is one or more alphabetic characters)
    specifies options affecting the rest of the RE.
    These options override any previously determined options (including
    both the RE flavor and case sensitivity).
    The available option letters are
    shown in <xref linkend="posix-embedded-options-table">.
   </para>

   <table id="posix-embedded-options-table">
    <title>ARE Embedded-Option Letters</title>

    <tgroup cols="2">
     <thead>
      <row>
       <entry>Option</entry>
       <entry>Description</entry>
      </row>
     </thead>

      <tbody>
       <row>
       <entry> <literal>b</> </entry>
       <entry> rest of RE is a BRE </entry>
       </row>

       <row>
       <entry> <literal>c</> </entry>
       <entry> case-sensitive matching (overrides operator type) </entry>
       </row>

       <row>
       <entry> <literal>e</> </entry>
       <entry> rest of RE is an ERE </entry>
       </row>

       <row>
       <entry> <literal>i</> </entry>
       <entry> case-insensitive matching (see
       <xref linkend="posix-matching-rules">) (overrides operator type) </entry>
       </row>

       <row>
       <entry> <literal>m</> </entry>
       <entry> historical synonym for <literal>n</> </entry>
       </row>

       <row>
       <entry> <literal>n</> </entry>
       <entry> newline-sensitive matching (see
       <xref linkend="posix-matching-rules">) </entry>
       </row>

       <row>
       <entry> <literal>p</> </entry>
       <entry> partial newline-sensitive matching (see
       <xref linkend="posix-matching-rules">) </entry>
       </row>

       <row>
       <entry> <literal>q</> </entry>
       <entry> rest of RE is a literal (<quote>quoted</>) string, all ordinary
       characters </entry>
       </row>

       <row>
       <entry> <literal>s</> </entry>
       <entry> non-newline-sensitive matching (default) </entry>
       </row>

       <row>
       <entry> <literal>t</> </entry>
       <entry> tight syntax (default; see below) </entry>
       </row>

       <row>
       <entry> <literal>w</> </entry>
       <entry> inverse partial newline-sensitive (<quote>weird</>) matching
       (see <xref linkend="posix-matching-rules">) </entry>
       </row>

       <row>
       <entry> <literal>x</> </entry>
       <entry> expanded syntax (see below) </entry>
       </row>
      </tbody>
     </tgroup>
    </table>

   <para>
    Embedded options take effect at the <literal>)</> terminating the sequence.
    They may appear only at the start of an ARE (after the
    <literal>***:</> director if any).
   </para>

   <para>
    In addition to the usual (<firstterm>tight</>) RE syntax, in which all
    characters are significant, there is an <firstterm>expanded</> syntax,
    available by specifying the embedded <literal>x</> option.
    In the expanded syntax,
    white-space characters in the RE are ignored, as are
    all characters between a <literal>#</>
    and the following newline (or the end of the RE).  This
    permits paragraphing and commenting a complex RE.
    There are three exceptions to that basic rule:

    <itemizedlist>
     <listitem>
      <para>
       a white-space character or <literal>#</> preceded by <literal>\</> is
       retained
      </para>
     </listitem>
     <listitem>
      <para>
       white space or <literal>#</> within a bracket expression is retained
      </para>
     </listitem>
     <listitem>
      <para>
       white space and comments cannot appear within multi-character symbols,
       such as <literal>(?:</>
      </para>
     </listitem>
    </itemizedlist>

    For this purpose, white-space characters are blank, tab, newline, and
    any character that belongs to the <replaceable>space</> character class.
   </para>

   <para>
    Finally, in an ARE, outside bracket expressions, the sequence
    <literal>(?#</><replaceable>ttt</><literal>)</>
    (where <replaceable>ttt</> is any text not containing a <literal>)</>)
    is a comment, completely ignored.
    Again, this is not allowed between the characters of
    multi-character symbols, like <literal>(?:</>.
    Such comments are more a historical artifact than a useful facility,
    and their use is deprecated; use the expanded syntax instead.
   </para>

   <para>
    <emphasis>None</> of these metasyntax extensions is available if
    an initial <literal>***=</> director
    has specified that the user's input be treated as a literal string
    rather than as an RE.
   </para>
   </sect3>

   <sect3 id="posix-matching-rules">
    <title>Regular Expression Matching Rules</title>

   <para>
    In the event that an RE could match more than one substring of a given
    string, the RE matches the one starting earliest in the string.
    If the RE could match more than one substring starting at that point,
    either the longest possible match or the shortest possible match will
    be taken, depending on whether the RE is <firstterm>greedy</> or
    <firstterm>non-greedy</>.
   </para>

   <para>
    Whether an RE is greedy or not is determined by the following rules:
    <itemizedlist>
     <listitem>
      <para>
       Most atoms, and all constraints, have no greediness attribute (because
       they cannot match variable amounts of text anyway).
      </para>
     </listitem>
     <listitem>
      <para>
       Adding parentheses around an RE does not change its greediness.
      </para>
     </listitem>
     <listitem>
      <para>
       A quantified atom with a fixed-repetition quantifier
       (<literal>{</><replaceable>m</><literal>}</>
       or
       <literal>{</><replaceable>m</><literal>}?</>)
       has the same greediness (possibly none) as the atom itself.
      </para>
     </listitem>
     <listitem>
      <para>
       A quantified atom with other normal quantifiers (including
       <literal>{</><replaceable>m</><literal>,</><replaceable>n</><literal>}</>
       with <replaceable>m</> equal to <replaceable>n</>)
       is greedy (prefers longest match).
      </para>
     </listitem>
     <listitem>
      <para>
       A quantified atom with a non-greedy quantifier (including
       <literal>{</><replaceable>m</><literal>,</><replaceable>n</><literal>}?</>
       with <replaceable>m</> equal to <replaceable>n</>)
       is non-greedy (prefers shortest match).
      </para>
     </listitem>
     <listitem>
      <para>
       A branch &mdash; that is, an RE that has no top-level
       <literal>|</> operator &mdash; has the same greediness as the first
       quantified atom in it that has a greediness attribute.
      </para>
     </listitem>
     <listitem>
      <para>
       An RE consisting of two or more branches connected by the
       <literal>|</> operator is always greedy.
      </para>
     </listitem>
    </itemizedlist>
   </para>

   <para>
    The above rules associate greediness attributes not only with individual
    quantified atoms, but with branches and entire REs that contain quantified
    atoms.  What that means is that the matching is done in such a way that
    the branch, or whole RE, matches the longest or shortest possible
    substring <emphasis>as a whole</>.  Once the length of the entire match
    is determined, the part of it that matches any particular subexpression
    is determined on the basis of the greediness attribute of that
    subexpression, with subexpressions starting earlier in the RE taking
    priority over ones starting later.
   </para>

   <para>
    An example of what this means:
<screen>
SELECT SUBSTRING('XY1234Z', 'Y*([0-9]{1,3})');
<lineannotation>Result: </lineannotation><computeroutput>123</computeroutput>
SELECT SUBSTRING('XY1234Z', 'Y*?([0-9]{1,3})');
<lineannotation>Result: </lineannotation><computeroutput>1</computeroutput>
</screen>
    In the first case, the RE as a whole is greedy because <literal>Y*</>
    is greedy.  It can match beginning at the <literal>Y</>, and it matches
    the longest possible string starting there, i.e., <literal>Y123</>.
    The output is the parenthesized part of that, or <literal>123</>.
    In the second case, the RE as a whole is non-greedy because <literal>Y*?</>
    is non-greedy.  It can match beginning at the <literal>Y</>, and it matches
    the shortest possible string starting there, i.e., <literal>Y1</>.
    The subexpression <literal>[0-9]{1,3}</> is greedy but it cannot change
    the decision as to the overall match length; so it is forced to match
    just <literal>1</>.
   </para>

   <para>
    In short, when an RE contains both greedy and non-greedy subexpressions,
    the total match length is either as long as possible or as short as
    possible, according to the attribute assigned to the whole RE.  The
    attributes assigned to the subexpressions only affect how much of that
    match they are allowed to <quote>eat</> relative to each other.
   </para>

   <para>
    The quantifiers <literal>{1,1}</> and <literal>{1,1}?</>
    can be used to force greediness or non-greediness, respectively,
    on a subexpression or a whole RE.
   </para>

   <para>
    Match lengths are measured in characters, not collating elements.
    An empty string is considered longer than no match at all.
    For example:
    <literal>bb*</>
    matches the three middle characters of <literal>abbbc</>;
    <literal>(week|wee)(night|knights)</>
    matches all ten characters of <literal>weeknights</>;
    when <literal>(.*).*</>
    is matched against <literal>abc</> the parenthesized subexpression
    matches all three characters; and when
    <literal>(a*)*</> is matched against <literal>bc</>
    both the whole RE and the parenthesized
    subexpression match an empty string.
   </para>

   <para>
    If case-independent matching is specified,
    the effect is much as if all case distinctions had vanished from the
    alphabet.
    When an alphabetic that exists in multiple cases appears as an
    ordinary character outside a bracket expression, it is effectively
    transformed into a bracket expression containing both cases,
    e.g. <literal>x</> becomes <literal>[xX]</>.
    When it appears inside a bracket expression, all case counterparts
    of it are added to the bracket expression, e.g.
    <literal>[x]</> becomes <literal>[xX]</>
    and <literal>[^x]</> becomes <literal>[^xX]</>.
   </para>

   <para>
    If newline-sensitive matching is specified, <literal>.</>
    and bracket expressions using <literal>^</>
    will never match the newline character
    (so that matches will never cross newlines unless the RE
    explicitly arranges it)
    and <literal>^</>and <literal>$</>
    will match the empty string after and before a newline
    respectively, in addition to matching at beginning and end of string
    respectively.
    But the ARE escapes <literal>\A</> and <literal>\Z</>
    continue to match beginning or end of string <emphasis>only</>.
   </para>

   <para>
    If partial newline-sensitive matching is specified,
    this affects <literal>.</> and bracket expressions
    as with newline-sensitive matching, but not <literal>^</>
    and <literal>$</>.
   </para>

   <para>
    If inverse partial newline-sensitive matching is specified,
    this affects <literal>^</> and <literal>$</>
    as with newline-sensitive matching, but not <literal>.</>
    and bracket expressions.
    This isn't very useful but is provided for symmetry.
   </para>
   </sect3>

   <sect3 id="posix-limits-compatibility">
    <title>Limits and Compatibility</title>

   <para>
    No particular limit is imposed on the length of REs in this
    implementation.  However,
    programs intended to be highly portable should not employ REs longer
    than 256 bytes,
    as a POSIX-compliant implementation can refuse to accept such REs.
   </para>

   <para>
    The only feature of AREs that is actually incompatible with
    POSIX EREs is that <literal>\</> does not lose its special
    significance inside bracket expressions.
    All other ARE features use syntax which is illegal or has
    undefined or unspecified effects in POSIX EREs;
    the <literal>***</> syntax of directors likewise is outside the POSIX
    syntax for both BREs and EREs.
   </para>

   <para>
    Many of the ARE extensions are borrowed from Perl, but some have
    been changed to clean them up, and a few Perl extensions are not present.
    Incompatibilities of note include <literal>\b</>, <literal>\B</>,
    the lack of special treatment for a trailing newline,
    the addition of complemented bracket expressions to the things
    affected by newline-sensitive matching,
    the restrictions on parentheses and back references in lookahead
    constraints, and the longest/shortest-match (rather than first-match)
    matching semantics.
   </para>

   <para>
    Two significant incompatibilities exist between AREs and the ERE syntax
    recognized by pre-7.4 releases of <productname>PostgreSQL</>:

    <itemizedlist>
     <listitem>
      <para>
       In AREs, <literal>\</> followed by an alphanumeric character is either
       an escape or an error, while in previous releases, it was just another
       way of writing the alphanumeric.
       This should not be much of a problem because there was no reason to
       write such a sequence in earlier releases.
      </para>
     </listitem>
     <listitem>
      <para>
       In AREs, <literal>\</> remains a special character within
       <literal>[]</>, so a literal <literal>\</> within a bracket
       expression must be written <literal>\\</>.
      </para>
     </listitem>
    </itemizedlist>

    While these differences are unlikely to create a problem for most
    applications, you can avoid them if necessary by
    setting <varname>regex_flavor</> to <literal>extended</>.
   </para>
   </sect3>

   <sect3 id="posix-basic-regexes">
    <title>Basic Regular Expressions</title>

   <para>
    BREs differ from EREs in several respects.
    <literal>|</>, <literal>+</>, and <literal>?</>
    are ordinary characters and there is no equivalent
    for their functionality.
    The delimiters for bounds are
    <literal>\{</> and <literal>\}</>,
    with <literal>{</> and <literal>}</>
    by themselves ordinary characters.
    The parentheses for nested subexpressions are
    <literal>\(</> and <literal>\)</>,
    with <literal>(</> and <literal>)</> by themselves ordinary characters.
    <literal>^</> is an ordinary character except at the beginning of the
    RE or the beginning of a parenthesized subexpression,
    <literal>$</> is an ordinary character except at the end of the
    RE or the end of a parenthesized subexpression,
    and <literal>*</> is an ordinary character if it appears at the beginning
    of the RE or the beginning of a parenthesized subexpression
    (after a possible leading <literal>^</>).
    Finally, single-digit back references are available, and
    <literal>\&lt;</> and <literal>\&gt;</>
    are synonyms for
    <literal>[[:&lt;:]]</> and <literal>[[:&gt;:]]</>
    respectively; no other escapes are available.
   </para>
   </sect3>

<!-- end re_syntax.n man page -->

  </sect2>
 </sect1>


  <sect1 id="functions-formatting">
   <title>Data Type Formatting Functions</title>

   <indexterm zone="functions-formatting">
    <primary>formatting</primary>
   </indexterm>

   <indexterm zone="functions-formatting">
    <primary>to_char</primary>
   </indexterm>

   <para>
    The <productname>PostgreSQL</productname> formatting functions
    provide a powerful set of tools for converting various data types
    (date/time, integer, floating point, numeric) to formatted strings
    and for converting from formatted strings to specific data types.
    <xref linkend="functions-formatting-table"> lists them.
    These functions all follow a common calling convention: the first
    argument is the value to be formatted and the second argument is a
    template that defines the output or input format.
   </para>
   <para>
    The <function>to_timestamp</function> function can also take a single 
    <type>double precision</type> argument to convert from Unix epoch to 
    <type>timestamp with time zone</type>.
    (<type>Integer</type> Unix epochs are implicitly cast to 
    <type>double precision</type>.)
   </para>

    <table id="functions-formatting-table">
     <title>Formatting Functions</title>
     <tgroup cols="4">
      <thead>
       <row>
        <entry>Function</entry>
        <entry>Return Type</entry>
        <entry>Description</entry>
        <entry>Example</entry>
       </row>
      </thead>
      <tbody>
       <row>
        <entry><literal><function>to_char</function>(<type>timestamp</type>, <type>text</type>)</literal></entry>
        <entry><type>text</type></entry>
        <entry>convert time stamp to string</entry>
        <entry><literal>to_char(current_timestamp, 'HH12:MI:SS')</literal></entry>
       </row>
       <row>
        <entry><literal><function>to_char</function>(<type>interval</type>, <type>text</type>)</literal></entry>
        <entry><type>text</type></entry>
        <entry>convert interval to string</entry>
        <entry><literal>to_char(interval '15h&nbsp;2m&nbsp;12s', 'HH24:MI:SS')</literal></entry>
       </row>
       <row>
        <entry><literal><function>to_char</function>(<type>int</type>, <type>text</type>)</literal></entry>
        <entry><type>text</type></entry>
        <entry>convert integer to string</entry>
        <entry><literal>to_char(125, '999')</literal></entry>
       </row>
       <row>
        <entry><literal><function>to_char</function>(<type>double precision</type>,
        <type>text</type>)</literal></entry>
        <entry><type>text</type></entry>
        <entry>convert real/double precision to string</entry>
        <entry><literal>to_char(125.8::real, '999D9')</literal></entry>
       </row>
       <row>
        <entry><literal><function>to_char</function>(<type>numeric</type>, <type>text</type>)</literal></entry>
        <entry><type>text</type></entry>
        <entry>convert numeric to string</entry>
        <entry><literal>to_char(-125.8, '999D99S')</literal></entry>
       </row>
       <row>
        <entry><literal><function>to_date</function>(<type>text</type>, <type>text</type>)</literal></entry>
        <entry><type>date</type></entry>
        <entry>convert string to date</entry>
        <entry><literal>to_date('05&nbsp;Dec&nbsp;2000', 'DD&nbsp;Mon&nbsp;YYYY')</literal></entry>
       </row>
       <row>
        <entry><literal><function>to_timestamp</function>(<type>text</type>, <type>text</type>)</literal></entry>
        <entry><type>timestamp with time zone</type></entry>
        <entry>convert string to time stamp</entry>
        <entry><literal>to_timestamp('05&nbsp;Dec&nbsp;2000', 'DD&nbsp;Mon&nbsp;YYYY')</literal></entry>
       </row>
       <row>
        <entry><literal><function>to_timestamp</function>(<type>double precision</type>)</literal></entry>
        <entry><type>timestamp with time zone</type></entry>
        <entry>convert UNIX epoch to time stamp</entry>
        <entry><literal>to_timestamp(200120400)</literal></entry>
       </row>
       <row>
        <entry><literal><function>to_number</function>(<type>text</type>, <type>text</type>)</literal></entry>
        <entry><type>numeric</type></entry>
        <entry>convert string to numeric</entry>
        <entry><literal>to_number('12,454.8-', '99G999D9S')</literal></entry>
       </row>
      </tbody>
     </tgroup>
    </table>

   <para>
    Warning: <literal><function>to_char</function>(<type>interval</type>, <type>text</type>)</literal> 
    is deprecated and should not be used in newly-written code. It will be removed in the next version.
   </para>

   <para>
    In an output template string (for <function>to_char</>), there are certain patterns that are
    recognized and replaced with appropriately-formatted data from the value
    to be formatted.  Any text that is not a template pattern is simply
    copied verbatim.  Similarly, in an input template string (for anything but <function>to_char</>), template patterns
    identify the parts of the input data string to be looked at and the
    values to be found there.
   </para>

  <para>
   <xref linkend="functions-formatting-datetime-table"> shows the
   template patterns available for formatting date and time values.
  </para>

    <table id="functions-formatting-datetime-table">
     <title>Template Patterns for Date/Time Formatting</title>
     <tgroup cols="2">
      <thead>
       <row>
        <entry>Pattern</entry>
        <entry>Description</entry>
       </row>
      </thead>
      <tbody>
       <row>
        <entry><literal>HH</literal></entry>
        <entry>hour of day (01-12)</entry>
       </row>
       <row>
        <entry><literal>HH12</literal></entry>
        <entry>hour of day (01-12)</entry>
       </row>       
       <row>
        <entry><literal>HH24</literal></entry>
        <entry>hour of day (00-23)</entry>
       </row>       
       <row>
        <entry><literal>MI</literal></entry>
        <entry>minute (00-59)</entry>
       </row>   
       <row>
        <entry><literal>SS</literal></entry>
        <entry>second (00-59)</entry>
       </row>
       <row>
        <entry><literal>MS</literal></entry>
        <entry>millisecond (000-999)</entry>
       </row>
       <row>
        <entry><literal>US</literal></entry>
        <entry>microsecond (000000-999999)</entry>
       </row>
       <row>
        <entry><literal>SSSS</literal></entry>
        <entry>seconds past midnight (0-86399)</entry>
       </row>
       <row>
        <entry><literal>AM</literal> or <literal>A.M.</literal> or
        <literal>PM</literal> or <literal>P.M.</literal></entry>
        <entry>meridian indicator (uppercase)</entry>
       </row>
       <row>
        <entry><literal>am</literal> or <literal>a.m.</literal> or
        <literal>pm</literal> or <literal>p.m.</literal></entry>
        <entry>meridian indicator (lowercase)</entry>
       </row>
       <row>
        <entry><literal>Y,YYY</literal></entry>
        <entry>year (4 and more digits) with comma</entry>
       </row>
       <row>
        <entry><literal>YYYY</literal></entry>
        <entry>year (4 and more digits)</entry>
       </row>
       <row>
        <entry><literal>YYY</literal></entry>
        <entry>last 3 digits of year</entry>
       </row>
       <row>
        <entry><literal>YY</literal></entry>
        <entry>last 2 digits of year</entry>
       </row>
       <row>
        <entry><literal>Y</literal></entry>
        <entry>last digit of year</entry>
       </row>
       <row>
        <entry><literal>IYYY</literal></entry>
        <entry>ISO year (4 and more digits)</entry>
       </row>
       <row>
        <entry><literal>IYY</literal></entry>
        <entry>last 3 digits of ISO year</entry>
       </row>
       <row>
        <entry><literal>IY</literal></entry>
        <entry>last 2 digits of ISO year</entry>
       </row>
       <row>
        <entry><literal>I</literal></entry>
        <entry>last digits of ISO year</entry>
       </row>
       <row>
        <entry><literal>BC</literal> or <literal>B.C.</literal> or
        <literal>AD</literal> or <literal>A.D.</literal></entry>
        <entry>era indicator (uppercase)</entry>
       </row>
       <row>
        <entry><literal>bc</literal> or <literal>b.c.</literal> or
        <literal>ad</literal> or <literal>a.d.</literal></entry>
        <entry>era indicator (lowercase)</entry>
       </row>
       <row>
        <entry><literal>MONTH</literal></entry>
        <entry>full uppercase month name (blank-padded to 9 chars)</entry>
       </row>
       <row>
        <entry><literal>Month</literal></entry>
        <entry>full mixed-case month name (blank-padded to 9 chars)</entry>
       </row>
       <row>
        <entry><literal>month</literal></entry>
        <entry>full lowercase month name (blank-padded to 9 chars)</entry>
       </row>
       <row>
        <entry><literal>MON</literal></entry>
        <entry>abbreviated uppercase month name (3 chars)</entry>
       </row>
       <row>
        <entry><literal>Mon</literal></entry>
        <entry>abbreviated mixed-case month name (3 chars)</entry>
       </row>
       <row>
        <entry><literal>mon</literal></entry>
        <entry>abbreviated lowercase month name (3 chars)</entry>
       </row>
       <row>
        <entry><literal>MM</literal></entry>
        <entry>month number (01-12)</entry>
       </row>
       <row>
        <entry><literal>DAY</literal></entry>
        <entry>full uppercase day name (blank-padded to 9 chars)</entry>
       </row>
       <row>
        <entry><literal>Day</literal></entry>
        <entry>full mixed-case day name (blank-padded to 9 chars)</entry>
       </row>
       <row>
        <entry><literal>day</literal></entry>
        <entry>full lowercase day name (blank-padded to 9 chars)</entry>
       </row>
       <row>
        <entry><literal>DY</literal></entry>
        <entry>abbreviated uppercase day name (3 chars)</entry>
       </row>
       <row>
        <entry><literal>Dy</literal></entry>
        <entry>abbreviated mixed-case day name (3 chars)</entry>
       </row>
       <row>
        <entry><literal>dy</literal></entry>
        <entry>abbreviated lowercase day name (3 chars)</entry>
       </row>
       <row>
        <entry><literal>DDD</literal></entry>
        <entry>day of year (001-366)</entry>
       </row>
       <row>
        <entry><literal>DD</literal></entry>
        <entry>day of month (01-31)</entry>
       </row>
       <row>
        <entry><literal>D</literal></entry>
        <entry>day of week (1-7; Sunday is 1)</entry>
       </row>
       <row>
        <entry><literal>W</literal></entry>
        <entry>week of month (1-5) (The first week starts on the first day of the month.)</entry>
       </row> 
       <row>
        <entry><literal>WW</literal></entry>
        <entry>week number of year (1-53) (The first week starts on the first day of the year.)</entry>
       </row>
       <row>
        <entry><literal>IW</literal></entry>
        <entry>ISO week number of year (The first Thursday of the new year is in week 1.)</entry>
       </row>
       <row>
        <entry><literal>CC</literal></entry>
        <entry>century (2 digits)</entry>
       </row>
       <row>
        <entry><literal>J</literal></entry>
        <entry>Julian Day (days since January 1, 4712 BC)</entry>
       </row>
       <row>
        <entry><literal>Q</literal></entry>
        <entry>quarter</entry>
       </row>
       <row>
        <entry><literal>RM</literal></entry>
        <entry>month in Roman numerals (I-XII; I=January) (uppercase)</entry>
       </row>
       <row>
        <entry><literal>rm</literal></entry>
        <entry>month in Roman numerals (i-xii; i=January) (lowercase)</entry>
       </row>
       <row>
        <entry><literal>TZ</literal></entry>
        <entry>time-zone name (uppercase)</entry>
       </row>
       <row>
        <entry><literal>tz</literal></entry>
        <entry>time-zone name (lowercase)</entry>
       </row>
      </tbody>
     </tgroup>
    </table>

   <para>
    Certain modifiers may be applied to any template pattern to alter its
    behavior.  For example, <literal>FMMonth</literal>
    is the <literal>Month</literal> pattern with the
    <literal>FM</literal> modifier.
    <xref linkend="functions-formatting-datetimemod-table"> shows the
    modifier patterns for date/time formatting.
   </para>

    <table id="functions-formatting-datetimemod-table">
     <title>Template Pattern Modifiers for Date/Time Formatting</title>
     <tgroup cols="3">
      <thead>
       <row>
        <entry>Modifier</entry>
        <entry>Description</entry>
        <entry>Example</entry>
       </row>
      </thead>
      <tbody>
       <row>
        <entry><literal>FM</literal> prefix</entry>
        <entry>fill mode (suppress padding blanks and zeroes)</entry>
        <entry><literal>FMMonth</literal></entry>
       </row>
       <row>
        <entry><literal>TH</literal> suffix</entry>
        <entry>uppercase ordinal number suffix</entry>
        <entry><literal>DDTH</literal></entry>
       </row>   
       <row>
        <entry><literal>th</literal> suffix</entry>
        <entry>lowercase ordinal number suffix</entry>
        <entry><literal>DDth</literal></entry>
       </row>
       <row>
        <entry><literal>FX</literal> prefix</entry>
        <entry>fixed format global option (see usage notes)</entry>
        <entry><literal>FX&nbsp;Month&nbsp;DD&nbsp;Day</literal></entry>
       </row>   
       <row>
        <entry><literal>SP</literal> suffix</entry>
        <entry>spell mode (not yet implemented)</entry>
        <entry><literal>DDSP</literal></entry>
       </row>       
      </tbody>
     </tgroup>
    </table>

   <para>
    Usage notes for date/time formatting:

    <itemizedlist>
     <listitem>
      <para>
       <literal>FM</literal> suppresses leading zeroes and trailing blanks
       that would otherwise be added to make the output of a pattern be
       fixed-width.
      </para>
     </listitem>

     <listitem>
      <para>
       <function>to_timestamp</function> and <function>to_date</function>
       skip multiple blank spaces in the input string if the <literal>FX</literal> option 
       is not used. <literal>FX</literal> must be specified as the first item
       in the template.  For example 
       <literal>to_timestamp('2000&nbsp;&nbsp;&nbsp;&nbsp;JUN', 'YYYY MON')</literal> is correct, but
       <literal>to_timestamp('2000&nbsp;&nbsp;&nbsp;&nbsp;JUN', 'FXYYYY MON')</literal> returns an error,
       because <function>to_timestamp</function> expects one space only.
      </para>
     </listitem>

     <listitem>
      <para>
       Ordinary text is allowed in <function>to_char</function>
       templates and will be output literally.  You can put a substring
       in double quotes to force it to be interpreted as literal text
       even if it contains pattern key words.  For example, in
       <literal>'"Hello Year "YYYY'</literal>, the <literal>YYYY</literal>
       will be replaced by the year data, but the single <literal>Y</literal> in <literal>Year</literal>
       will not be.
      </para>
     </listitem>

     <listitem>
      <para>
       If you want to have a double quote in the output you must
       precede it with a backslash, for example <literal>'\\"YYYY
       Month\\"'</literal>. <!-- "" font-lock sanity :-) -->
       (Two backslashes are necessary because the backslash already
       has a special meaning in a string constant.)
      </para>
     </listitem>

     <listitem>
      <para>
       The <literal>YYYY</literal> conversion from string to <type>timestamp</type> or
       <type>date</type> has a restriction if you use a year with more than 4 digits. You must
       use some non-digit character or template after <literal>YYYY</literal>,
       otherwise the year is always interpreted as 4 digits. For example
       (with the year 20000):
       <literal>to_date('200001131', 'YYYYMMDD')</literal> will be 
       interpreted as a 4-digit year; instead use a non-digit 
       separator after the year, like
       <literal>to_date('20000-1131', 'YYYY-MMDD')</literal> or
       <literal>to_date('20000Nov31', 'YYYYMonDD')</literal>.
      </para>
     </listitem>

     <listitem>
      <para>
       In conversions from string to <type>timestamp</type> or
       <type>date</type>, the <literal>CC</literal> field is ignored if there
       is a <literal>YYY</literal>, <literal>YYYY</literal> or
       <literal>Y,YYY</literal> field. If <literal>CC</literal> is used with
       <literal>YY</literal> or <literal>Y</literal> then the year is computed
       as <literal>(CC-1)*100+YY</literal>.
      </para>
     </listitem>

     <listitem>
      <para>
       Millisecond (<literal>MS</literal>) and microsecond (<literal>US</literal>)
       values in a conversion from string to <type>timestamp</type> are used as part of the
       seconds after the decimal point. For example 
       <literal>to_timestamp('12:3', 'SS:MS')</literal> is not 3 milliseconds,
       but 300, because the conversion counts it as 12 + 0.3 seconds.
       This means for the format <literal>SS:MS</literal>, the input values
       <literal>12:3</literal>, <literal>12:30</literal>, and <literal>12:300</literal> specify the
       same number of milliseconds. To get three milliseconds, one must use
       <literal>12:003</literal>, which the conversion counts as
       12 + 0.003 = 12.003 seconds.
      </para>

      <para>
       Here is a more 
       complex example: 
       <literal>to_timestamp('15:12:02.020.001230', 'HH:MI:SS.MS.US')</literal>
       is 15 hours, 12 minutes, and 2 seconds + 20 milliseconds +
       1230 microseconds = 2.021230 seconds. 
      </para>
     </listitem>

     <listitem>
      <para><function>to_char</function>'s day of the week numbering
        (see the 'D' formatting pattern) is different from that of the 
        <function>extract</function> function.
      </para>
     </listitem>
    </itemizedlist>
   </para>

  <para>
   <xref linkend="functions-formatting-numeric-table"> shows the
   template patterns available for formatting numeric values.
  </para>

    <table id="functions-formatting-numeric-table">
     <title>Template Patterns for Numeric Formatting</title>
     <tgroup cols="2">
      <thead>
       <row>
        <entry>Pattern</entry>
        <entry>Description</entry>
       </row>
      </thead>
      <tbody>
       <row>
        <entry><literal>9</literal></entry>
        <entry>value with the specified number of digits</entry>
       </row>
       <row>
        <entry><literal>0</literal></entry>
        <entry>value with leading zeros</entry>
       </row>
       <row>
        <entry><literal>.</literal> (period)</entry>
        <entry>decimal point</entry>
       </row>       
       <row>
        <entry><literal>,</literal> (comma)</entry>
        <entry>group (thousand) separator</entry>
       </row>
       <row>
        <entry><literal>PR</literal></entry>
        <entry>negative value in angle brackets</entry>
       </row>
       <row>
        <entry><literal>S</literal></entry>
        <entry>sign anchored to number (uses locale)</entry>
       </row>
       <row>
        <entry><literal>L</literal></entry>
        <entry>currency symbol (uses locale)</entry>
       </row>
       <row>
        <entry><literal>D</literal></entry>
        <entry>decimal point (uses locale)</entry>
       </row>
       <row>
        <entry><literal>G</literal></entry>
        <entry>group separator (uses locale)</entry>
       </row>
       <row>
        <entry><literal>MI</literal></entry>
        <entry>minus sign in specified position (if number &lt; 0)</entry>
       </row>
       <row>
        <entry><literal>PL</literal></entry>
        <entry>plus sign in specified position (if number &gt; 0)</entry>
       </row>
       <row>
        <entry><literal>SG</literal></entry>
        <entry>plus/minus sign in specified position</entry>
       </row>
       <row>
        <entry><literal>RN</literal></entry>
        <entry>roman numeral (input between 1 and 3999)</entry>
       </row>
       <row>
        <entry><literal>TH</literal> or <literal>th</literal></entry>
        <entry>ordinal number suffix</entry>
       </row>
       <row>
        <entry><literal>V</literal></entry>
        <entry>shift specified number of digits (see notes)</entry>
       </row>
       <row>
        <entry><literal>EEEE</literal></entry>
        <entry>scientific notation (not implemented yet)</entry>
       </row>
      </tbody>
     </tgroup>
    </table>

   <para>
    Usage notes for numeric formatting:

    <itemizedlist>
     <listitem>
      <para>
       A sign formatted using <literal>SG</literal>, <literal>PL</literal>, or
       <literal>MI</literal> is not anchored to
       the number; for example,
       <literal>to_char(-12, 'S9999')</literal> produces <literal>'&nbsp;&nbsp;-12'</literal>,
       but <literal>to_char(-12, 'MI9999')</literal> produces <literal>'-&nbsp;&nbsp;12'</literal>.
       The Oracle implementation does not allow the use of
       <literal>MI</literal> ahead of <literal>9</literal>, but rather
       requires that <literal>9</literal> precede
       <literal>MI</literal>.
      </para>
     </listitem>

     <listitem>
      <para>
       <literal>9</literal> results in a value with the same number of 
       digits as there are <literal>9</literal>s. If a digit is
       not available it outputs a space.
      </para>
     </listitem>

     <listitem>
      <para>
       <literal>TH</literal> does not convert values less than zero
       and does not convert fractional numbers.
      </para>
     </listitem>

     <listitem>
      <para>
       <literal>PL</literal>, <literal>SG</literal>, and
       <literal>TH</literal> are <productname>PostgreSQL</productname>
       extensions. 
      </para>
     </listitem>

     <listitem>
      <para>
       <literal>V</literal> effectively
       multiplies the input values by
       <literal>10^<replaceable>n</replaceable></literal>, where
       <replaceable>n</replaceable> is the number of digits following
       <literal>V</literal>. 
       <function>to_char</function> does not support the use of
       <literal>V</literal> combined with a decimal point.
       (E.g., <literal>99.9V99</literal> is not allowed.)
      </para>
     </listitem>
    </itemizedlist>
   </para>   

  <para>
   <xref linkend="functions-formatting-examples-table"> shows some
   examples of the use of the <function>to_char</function> function.
  </para>

    <table id="functions-formatting-examples-table">
     <title><function>to_char</function> Examples</title>
     <tgroup cols="2">
      <thead>
       <row>
        <entry>Expression</entry>
        <entry>Result</entry>
       </row>
      </thead>
      <tbody>
       <row>
        <entry><literal>to_char(current_timestamp, 'Day,&nbsp;DD&nbsp;&nbsp;HH12:MI:SS')</literal></entry>
        <entry><literal>'Tuesday&nbsp;&nbsp;,&nbsp;06&nbsp;&nbsp;05:39:18'</literal></entry>
       </row>
       <row>
        <entry><literal>to_char(current_timestamp, 'FMDay,&nbsp;FMDD&nbsp;&nbsp;HH12:MI:SS')</literal></entry>
        <entry><literal>'Tuesday,&nbsp;6&nbsp;&nbsp;05:39:18'</literal></entry>
       </row>          
       <row>
        <entry><literal>to_char(-0.1, '99.99')</literal></entry>
        <entry><literal>'&nbsp;&nbsp;-.10'</literal></entry>
       </row>
       <row>
        <entry><literal>to_char(-0.1, 'FM9.99')</literal></entry>
        <entry><literal>'-.1'</literal></entry>
       </row>
       <row>
        <entry><literal>to_char(0.1, '0.9')</literal></entry>
        <entry><literal>'&nbsp;0.1'</literal></entry>
       </row>
       <row>
        <entry><literal>to_char(12, '9990999.9')</literal></entry>
        <entry><literal>'&nbsp;&nbsp;&nbsp;&nbsp;0012.0'</literal></entry>
       </row>
       <row>
        <entry><literal>to_char(12, 'FM9990999.9')</literal></entry>
        <entry><literal>'0012.'</literal></entry>
       </row>
       <row>
        <entry><literal>to_char(485, '999')</literal></entry>
        <entry><literal>'&nbsp;485'</literal></entry>
       </row>
       <row>
        <entry><literal>to_char(-485, '999')</literal></entry>
        <entry><literal>'-485'</literal></entry>
       </row>
       <row>
        <entry><literal>to_char(485, '9&nbsp;9&nbsp;9')</literal></entry>
        <entry><literal>'&nbsp;4&nbsp;8&nbsp;5'</literal></entry>
       </row>
       <row>
        <entry><literal>to_char(1485, '9,999')</literal></entry>
        <entry><literal>'&nbsp;1,485'</literal></entry>
       </row>
       <row>
        <entry><literal>to_char(1485, '9G999')</literal></entry>
        <entry><literal>'&nbsp;1&nbsp;485'</literal></entry>
       </row>
       <row>
        <entry><literal>to_char(148.5, '999.999')</literal></entry>
        <entry><literal>'&nbsp;148.500'</literal></entry>
       </row>
       <row>
        <entry><literal>to_char(148.5, 'FM999.999')</literal></entry>
        <entry><literal>'148.5'</literal></entry>
       </row>
       <row>
        <entry><literal>to_char(148.5, 'FM999.990')</literal></entry>
        <entry><literal>'148.500'</literal></entry>
       </row>
       <row>
        <entry><literal>to_char(148.5, '999D999')</literal></entry>
        <entry><literal>'&nbsp;148,500'</literal></entry>        
       </row>
       <row>
        <entry><literal>to_char(3148.5, '9G999D999')</literal></entry>
        <entry><literal>'&nbsp;3&nbsp;148,500'</literal></entry>
       </row>
       <row>
        <entry><literal>to_char(-485, '999S')</literal></entry>
        <entry><literal>'485-'</literal></entry>
       </row>
       <row>            
        <entry><literal>to_char(-485, '999MI')</literal></entry>
        <entry><literal>'485-'</literal></entry>        
       </row>
       <row>
        <entry><literal>to_char(485, '999MI')</literal></entry>
        <entry><literal>'485&nbsp;'</literal></entry>           
       </row>
       <row>
        <entry><literal>to_char(485, 'FM999MI')</literal></entry>
        <entry><literal>'485'</literal></entry>         
       </row>
       <row>
        <entry><literal>to_char(485, 'PL999')</literal></entry>
        <entry><literal>'+485'</literal></entry>        
       </row>
       <row>            
        <entry><literal>to_char(485, 'SG999')</literal></entry>
        <entry><literal>'+485'</literal></entry>        
       </row>
       <row>
        <entry><literal>to_char(-485, 'SG999')</literal></entry>
        <entry><literal>'-485'</literal></entry>        
       </row>
       <row>
        <entry><literal>to_char(-485, '9SG99')</literal></entry>
        <entry><literal>'4-85'</literal></entry>        
       </row>
       <row>
        <entry><literal>to_char(-485, '999PR')</literal></entry>
        <entry><literal>'&lt;485&gt;'</literal></entry>         
       </row>
       <row>
        <entry><literal>to_char(485, 'L999')</literal></entry>
        <entry><literal>'DM&nbsp;485</literal></entry>   
       </row>
       <row>
        <entry><literal>to_char(485, 'RN')</literal></entry>            
        <entry><literal>'&nbsp;&nbsp;&nbsp;&nbsp;&nbsp;&nbsp;&nbsp;&nbsp;CDLXXXV'</literal></entry>
       </row>
       <row>
        <entry><literal>to_char(485, 'FMRN')</literal></entry>  
        <entry><literal>'CDLXXXV'</literal></entry>
       </row>
       <row>
        <entry><literal>to_char(5.2, 'FMRN')</literal></entry>
        <entry><literal>'V'</literal></entry>           
       </row>
       <row>
        <entry><literal>to_char(482, '999th')</literal></entry>
        <entry><literal>'&nbsp;482nd'</literal></entry>                         
       </row>
       <row>
        <entry><literal>to_char(485, '"Good&nbsp;number:"999')</literal></entry>
        <entry><literal>'Good&nbsp;number:&nbsp;485'</literal></entry>
       </row>
       <row>
        <entry><literal>to_char(485.8, '"Pre:"999"&nbsp;Post:"&nbsp;.999')</literal></entry>
        <entry><literal>'Pre:&nbsp;485&nbsp;Post:&nbsp;.800'</literal></entry>
       </row>
       <row>
        <entry><literal>to_char(12, '99V999')</literal></entry>         
        <entry><literal>'&nbsp;12000'</literal></entry>
       </row>
       <row>
        <entry><literal>to_char(12.4, '99V999')</literal></entry>
        <entry><literal>'&nbsp;12400'</literal></entry>
       </row>
       <row>            
        <entry><literal>to_char(12.45, '99V9')</literal></entry>
        <entry><literal>'&nbsp;125'</literal></entry>
       </row>
      </tbody>
     </tgroup>
    </table>

  </sect1>


  <sect1 id="functions-datetime">
   <title>Date/Time Functions and Operators</title>

  <para>
   <xref linkend="functions-datetime-table"> shows the available
   functions for date/time value processing, with details appearing in
   the following subsections.  <xref
   linkend="operators-datetime-table"> illustrates the behaviors of
   the basic arithmetic operators (<literal>+</literal>,
   <literal>*</literal>, etc.).  For formatting functions, refer to
   <xref linkend="functions-formatting">.  You should be familiar with
   the background information on date/time data types from <xref
   linkend="datatype-datetime">.
  </para>

  <para>
   All the functions and operators described below that take <type>time</type> or <type>timestamp</type>
   inputs actually come in two variants: one that takes <type>time with time zone</type> or <type>timestamp
   with time zone</type>, and one that takes <type>time without time zone</type> or <type>timestamp without time zone</type>.
   For brevity, these variants are not shown separately.  Also, the
   <literal>+</> and <literal>*</> operators come in commutative pairs (for
   example both date + integer and integer + date); we show only one of each
   such pair.
  </para>

    <table id="operators-datetime-table">
     <title>Date/Time Operators</title>

     <tgroup cols="3">
      <thead>
       <row>
        <entry>Operator</entry>
        <entry>Example</entry>
        <entry>Result</entry>
       </row>
      </thead>

      <tbody>
       <row>
        <entry> <literal>+</literal> </entry>
        <entry><literal>date '2001-09-28' + integer '7'</literal></entry>
        <entry><literal>date '2001-10-05'</literal></entry>
       </row>

       <row>
        <entry> <literal>+</literal> </entry>
        <entry><literal>date '2001-09-28' + interval '1 hour'</literal></entry>
        <entry><literal>timestamp '2001-09-28 01:00'</literal></entry>
       </row>

       <row>
        <entry> <literal>+</literal> </entry>
        <entry><literal>date '2001-09-28' + time '03:00'</literal></entry>
        <entry><literal>timestamp '2001-09-28 03:00'</literal></entry>
       </row>

       <row>
        <entry> <literal>+</literal> </entry>
        <entry><literal>interval '1 day' + interval '1 hour'</literal></entry>
        <entry><literal>interval '1 day 01:00'</literal></entry>
       </row>

       <row>
        <entry> <literal>+</literal> </entry>
        <entry><literal>timestamp '2001-09-28 01:00' + interval '23 hours'</literal></entry>
        <entry><literal>timestamp '2001-09-29 00:00'</literal></entry>
       </row>

       <row>
        <entry> <literal>+</literal> </entry>
        <entry><literal>time '01:00' + interval '3 hours'</literal></entry>
        <entry><literal>time '04:00'</literal></entry>
       </row>

       <row>
        <entry> <literal>-</literal> </entry>
        <entry><literal>- interval '23 hours'</literal></entry>
        <entry><literal>interval '-23:00'</literal></entry>
       </row>

       <row>
        <entry> <literal>-</literal> </entry>
        <entry><literal>date '2001-10-01' - date '2001-09-28'</literal></entry>
        <entry><literal>integer '3'</literal></entry>
       </row>

       <row>
        <entry> <literal>-</literal> </entry>
        <entry><literal>date '2001-10-01' - integer '7'</literal></entry>
        <entry><literal>date '2001-09-24'</literal></entry>
       </row>

       <row>
        <entry> <literal>-</literal> </entry>
        <entry><literal>date '2001-09-28' - interval '1 hour'</literal></entry>
        <entry><literal>timestamp '2001-09-27 23:00'</literal></entry>
       </row>

       <row>
        <entry> <literal>-</literal> </entry>
        <entry><literal>time '05:00' - time '03:00'</literal></entry>
        <entry><literal>interval '02:00'</literal></entry>
       </row>

       <row>
        <entry> <literal>-</literal> </entry>
        <entry><literal>time '05:00' - interval '2 hours'</literal></entry>
        <entry><literal>time '03:00'</literal></entry>
       </row>

       <row>
        <entry> <literal>-</literal> </entry>
        <entry><literal>timestamp '2001-09-28 23:00' - interval '23 hours'</literal></entry>
        <entry><literal>timestamp '2001-09-28 00:00'</literal></entry>
       </row>

       <row>
        <entry> <literal>-</literal> </entry>
        <entry><literal>interval '1 day' - interval '1 hour'</literal></entry>
        <entry><literal>interval '23:00'</literal></entry>
       </row>

       <row>
        <entry> <literal>-</literal> </entry>
        <entry><literal>timestamp '2001-09-29 03:00' - timestamp '2001-09-27 12:00'</literal></entry>
        <entry><literal>interval '1 day 15:00'</literal></entry>
       </row>

       <row>
        <entry> <literal>*</literal> </entry>
        <entry><literal>interval '1 hour' * double precision '3.5'</literal></entry>
        <entry><literal>interval '03:30'</literal></entry>
       </row>

       <row>
        <entry> <literal>/</literal> </entry>
        <entry><literal>interval '1 hour' / double precision '1.5'</literal></entry>
        <entry><literal>interval '00:40'</literal></entry>
       </row>
      </tbody>
     </tgroup>
    </table>

    <table id="functions-datetime-table">
     <title>Date/Time Functions</title>
     <tgroup cols="5">
      <thead>
       <row>
        <entry>Function</entry>
        <entry>Return Type</entry>
        <entry>Description</entry>
        <entry>Example</entry>
        <entry>Result</entry>
       </row>
      </thead>

      <tbody>
       <row>
        <entry><literal><function>age</function>(<type>timestamp</type>, <type>timestamp</type>)</literal></entry>
        <entry><type>interval</type></entry>
        <entry>Subtract arguments, producing a <quote>symbolic</> result that
        uses years and months</entry>
        <entry><literal>age(timestamp '2001-04-10', timestamp '1957-06-13')</literal></entry>
        <entry><literal>43 years 9 mons 27 days</literal></entry>
       </row>

       <row>
        <entry><literal><function>age</function>(<type>timestamp</type>)</literal></entry>
        <entry><type>interval</type></entry>
        <entry>Subtract from <function>current_date</function></entry>
        <entry><literal>age(timestamp '1957-06-13')</literal></entry>
        <entry><literal>43 years 8 mons 3 days</literal></entry>
       </row>

       <row>
        <entry><literal><function>current_date</function></literal></entry>
        <entry><type>date</type></entry>
        <entry>Today's date; see <xref linkend="functions-datetime-current">
        </entry>
        <entry></entry>
        <entry></entry>
       </row>

       <row>
        <entry><literal><function>current_time</function></literal></entry>
        <entry><type>time with time zone</type></entry>
        <entry>Time of day; see <xref linkend="functions-datetime-current">
        </entry>
        <entry></entry>
        <entry></entry>
       </row>

       <row>
        <entry><literal><function>current_timestamp</function></literal></entry>
        <entry><type>timestamp with time zone</type></entry>
        <entry>Date and time; see <xref linkend="functions-datetime-current">
        </entry>
        <entry></entry>
        <entry></entry>
       </row>

       <row>
        <entry><literal><function>date_part</function>(<type>text</type>, <type>timestamp</type>)</literal></entry>
        <entry><type>double precision</type></entry>
        <entry>Get subfield (equivalent to
         <function>extract</function>); see <xref linkend="functions-datetime-extract">
        </entry>
        <entry><literal>date_part('hour', timestamp '2001-02-16 20:38:40')</literal></entry>
        <entry><literal>20</literal></entry>
       </row>

       <row>
        <entry><literal><function>date_part</function>(<type>text</type>, <type>interval</type>)</literal></entry>
        <entry><type>double precision</type></entry>
        <entry>Get subfield (equivalent to
         <function>extract</function>); see <xref linkend="functions-datetime-extract">
        </entry>
        <entry><literal>date_part('month', interval '2 years 3 months')</literal></entry>
        <entry><literal>3</literal></entry>
       </row>

       <row>
        <entry><literal><function>date_trunc</function>(<type>text</type>, <type>timestamp</type>)</literal></entry>
        <entry><type>timestamp</type></entry>
        <entry>Truncate to specified precision; see also <xref
                                                        linkend="functions-datetime-trunc">
        </entry>
        <entry><literal>date_trunc('hour', timestamp '2001-02-16 20:38:40')</literal></entry>
        <entry><literal>2001-02-16 20:00:00</literal></entry>
       </row>

       <row>
        <entry><literal><function>extract</function>(<parameter>field</parameter> from
         <type>timestamp</type>)</literal></entry>
        <entry><type>double precision</type></entry>
        <entry>Get subfield; see <xref linkend="functions-datetime-extract">
        </entry>
        <entry><literal>extract(hour from timestamp '2001-02-16 20:38:40')</literal></entry>
        <entry><literal>20</literal></entry>
       </row>

       <row>
        <entry><literal><function>extract</function>(<parameter>field</parameter> from
         <type>interval</type>)</literal></entry>
        <entry><type>double precision</type></entry>
        <entry>Get subfield; see <xref linkend="functions-datetime-extract">
        </entry>
        <entry><literal>extract(month from interval '2 years 3 months')</literal></entry>
        <entry><literal>3</literal></entry>
       </row>

       <row>
        <entry><literal><function>isfinite</function>(<type>timestamp</type>)</literal></entry>
        <entry><type>boolean</type></entry>
        <entry>Test for finite time stamp (not equal to infinity)</entry>
        <entry><literal>isfinite(timestamp '2001-02-16 21:28:30')</literal></entry>
        <entry><literal>true</literal></entry>
       </row>

       <row>
        <entry><literal><function>isfinite</function>(<type>interval</type>)</literal></entry>
        <entry><type>boolean</type></entry>
        <entry>Test for finite interval</entry>
        <entry><literal>isfinite(interval '4 hours')</literal></entry>
        <entry><literal>true</literal></entry>
       </row>

       <row>
        <entry><literal><function>localtime</function></literal></entry>
        <entry><type>time</type></entry>
        <entry>Time of day; see <xref linkend="functions-datetime-current">
        </entry>
        <entry></entry>
        <entry></entry>
       </row>

       <row>
        <entry><literal><function>localtimestamp</function></literal></entry>
        <entry><type>timestamp</type></entry>
        <entry>Date and time; see <xref linkend="functions-datetime-current">
        </entry>
        <entry></entry>
        <entry></entry>
       </row>

       <row>
        <entry><literal><function>now</function>()</literal></entry>
        <entry><type>timestamp with time zone</type></entry>
        <entry>Current date and time (equivalent to
         <function>current_timestamp</function>); see <xref
                                                     linkend="functions-datetime-current">
        </entry>
        <entry></entry>
        <entry></entry>
       </row>

       <row>
        <entry><literal><function>timeofday()</function></literal></entry>
        <entry><type>text</type></entry>
        <entry>Current date and time; see <xref
                                         linkend="functions-datetime-current">
        </entry>
        <entry></entry>
        <entry></entry>
       </row>

      </tbody>
     </tgroup>
    </table>

   <para>
    In addition to these functions, the SQL <literal>OVERLAPS</> operator is
    supported:
<synopsis>
( <replaceable>start1</replaceable>, <replaceable>end1</replaceable> ) OVERLAPS ( <replaceable>start2</replaceable>, <replaceable>end2</replaceable> )
( <replaceable>start1</replaceable>, <replaceable>length1</replaceable> ) OVERLAPS ( <replaceable>start2</replaceable>, <replaceable>length2</replaceable> )
</synopsis>
    This expression yields true when two time periods (defined by their
    endpoints) overlap, false when they do not overlap.  The endpoints
    can be specified as pairs of dates, times, or time stamps; or as
    a date, time, or time stamp followed by an interval.
   </para>

<screen>
SELECT (DATE '2001-02-16', DATE '2001-12-21') OVERLAPS
       (DATE '2001-10-30', DATE '2002-10-30');
<lineannotation>Result: </lineannotation><computeroutput>true</computeroutput>
SELECT (DATE '2001-02-16', INTERVAL '100 days') OVERLAPS
       (DATE '2001-10-30', DATE '2002-10-30');
<lineannotation>Result: </lineannotation><computeroutput>false</computeroutput>
</screen>

  <sect2 id="functions-datetime-extract">
   <title><function>EXTRACT</function>, <function>date_part</function></title>

<synopsis>
EXTRACT (<replaceable>field</replaceable> FROM <replaceable>source</replaceable>)
</synopsis>

   <para>
    The <function>extract</function> function retrieves subfields
    such as year or hour from date/time values.
    <replaceable>source</replaceable> must be a value expression of
    type <type>timestamp</type>, <type>time</type>, or <type>interval</type>.
    (Expressions of type <type>date</type> will
    be cast to <type>timestamp</type> and can therefore be used as
    well.)  <replaceable>field</replaceable> is an identifier or
    string that selects what field to extract from the source value.
    The <function>extract</function> function returns values of type
    <type>double precision</type>.
    The following are valid field names:

    <!-- alphabetical -->
    <variablelist>
     <varlistentry>
      <term><literal>century</literal></term>
      <listitem>
       <para>
        The century
       </para>

<screen>
SELECT EXTRACT(CENTURY FROM TIMESTAMP '2000-12-16 12:21:13');
<lineannotation>Result: </lineannotation><computeroutput>20</computeroutput>
SELECT EXTRACT(CENTURY FROM TIMESTAMP '2001-02-16 20:38:40');
<lineannotation>Result: </lineannotation><computeroutput>21</computeroutput>
</screen>

       <para>
        The first century starts at 0001-01-01 00:00:00 AD, although
        they did not know it at the time. This definition applies to all
        Gregorian calendar countries. There is no century number 0,
        you go from -1 to 1.

        If you disagree with this, please write your complaint to:
        Pope, Cathedral Saint-Peter of Roma, Vatican.
       </para>

       <para>
        <productname>PostgreSQL</productname> releases before 8.0 did not
        follow the conventional numbering of centuries, but just returned
        the year field divided by 100.
       </para>
      </listitem>
     </varlistentry>

     <varlistentry>
      <term><literal>day</literal></term>
      <listitem>
       <para>
        The day (of the month) field (1 - 31)
       </para>

<screen>
SELECT EXTRACT(DAY FROM TIMESTAMP '2001-02-16 20:38:40');
<lineannotation>Result: </lineannotation><computeroutput>16</computeroutput>
</screen>
      </listitem>
     </varlistentry>

     <varlistentry>
      <term><literal>decade</literal></term>
      <listitem>
       <para>
        The year field divided by 10
       </para>

<screen>
SELECT EXTRACT(DECADE FROM TIMESTAMP '2001-02-16 20:38:40');
<lineannotation>Result: </lineannotation><computeroutput>200</computeroutput>
</screen>
      </listitem>
     </varlistentry>

     <varlistentry>
      <term><literal>dow</literal></term>
      <listitem>
       <para>
        The day of the week (0 - 6; Sunday is 0) (for
        <type>timestamp</type> values only)
       </para>

<screen>
SELECT EXTRACT(DOW FROM TIMESTAMP '2001-02-16 20:38:40');
<lineannotation>Result: </lineannotation><computeroutput>5</computeroutput>
</screen>
       <para>
        Note that <function>extract</function>'s day of the week numbering is 
        different from that of the <function>to_char</function> function.
       </para>

      </listitem>
     </varlistentry>

     <varlistentry>
      <term><literal>doy</literal></term>
      <listitem>
       <para>
        The day of the year (1 - 365/366) (for <type>timestamp</type> values only)
       </para>

<screen>
SELECT EXTRACT(DOY FROM TIMESTAMP '2001-02-16 20:38:40');
<lineannotation>Result: </lineannotation><computeroutput>47</computeroutput>
</screen>
      </listitem>
     </varlistentry>

     <varlistentry>
      <term><literal>epoch</literal></term>
      <listitem>
       <para>
        For <type>date</type> and <type>timestamp</type> values, the
        number of seconds since 1970-01-01 00:00:00-00 (can be negative);
        for <type>interval</type> values, the total number
        of seconds in the interval
       </para>

<screen>
SELECT EXTRACT(EPOCH FROM TIMESTAMP WITH TIME ZONE '2001-02-16 20:38:40-08');
<lineannotation>Result: </lineannotation><computeroutput>982384720</computeroutput>

SELECT EXTRACT(EPOCH FROM INTERVAL '5 days 3 hours');
<lineannotation>Result: </lineannotation><computeroutput>442800</computeroutput>
</screen>

       <para>
        Here is how you can convert an epoch value back to a time
        stamp:
       </para>

<screen>
SELECT TIMESTAMP WITH TIME ZONE 'epoch' + 982384720 * INTERVAL '1 second';
</screen>
      </listitem>
     </varlistentry>

     <varlistentry>
      <term><literal>hour</literal></term>
      <listitem>
       <para>
        The hour field (0 - 23)
       </para>

<screen>
SELECT EXTRACT(HOUR FROM TIMESTAMP '2001-02-16 20:38:40');
<lineannotation>Result: </lineannotation><computeroutput>20</computeroutput>
</screen>
      </listitem>
     </varlistentry>

     <varlistentry>
      <term><literal>microseconds</literal></term>
      <listitem>
       <para>
        The seconds field, including fractional parts, multiplied by 1
        000 000.  Note that this includes full seconds.
       </para>

<screen>
SELECT EXTRACT(MICROSECONDS FROM TIME '17:12:28.5');
<lineannotation>Result: </lineannotation><computeroutput>28500000</computeroutput>
</screen>
      </listitem>
     </varlistentry>

     <varlistentry>
      <term><literal>millennium</literal></term>
      <listitem>
       <para>
        The millennium
       </para>

<screen>
SELECT EXTRACT(MILLENNIUM FROM TIMESTAMP '2001-02-16 20:38:40');
<lineannotation>Result: </lineannotation><computeroutput>3</computeroutput>
</screen>

       <para>
        Years in the 1900s are in the second millennium.
        The third millennium starts January 1, 2001.
       </para>

       <para>
        <productname>PostgreSQL</productname> releases before 8.0 did not
        follow the conventional numbering of millennia, but just returned
        the year field divided by 1000.
       </para>
      </listitem>
     </varlistentry>

     <varlistentry>
      <term><literal>milliseconds</literal></term>
      <listitem>
       <para>
        The seconds field, including fractional parts, multiplied by
        1000.  Note that this includes full seconds.
       </para>

<screen>
SELECT EXTRACT(MILLISECONDS FROM TIME '17:12:28.5');
<lineannotation>Result: </lineannotation><computeroutput>28500</computeroutput>
</screen>
      </listitem>
     </varlistentry>

     <varlistentry>
      <term><literal>minute</literal></term>
      <listitem>
       <para>
        The minutes field (0 - 59)
       </para>

<screen>
SELECT EXTRACT(MINUTE FROM TIMESTAMP '2001-02-16 20:38:40');
<lineannotation>Result: </lineannotation><computeroutput>38</computeroutput>
</screen>
      </listitem>
     </varlistentry>

     <varlistentry>
      <term><literal>month</literal></term>
      <listitem>
       <para>
        For <type>timestamp</type> values, the number of the month
        within the year (1 - 12) ; for <type>interval</type> values
        the number of months, modulo 12 (0 - 11)
       </para>

<screen>
SELECT EXTRACT(MONTH FROM TIMESTAMP '2001-02-16 20:38:40');
<lineannotation>Result: </lineannotation><computeroutput>2</computeroutput>

SELECT EXTRACT(MONTH FROM INTERVAL '2 years 3 months');
<lineannotation>Result: </lineannotation><computeroutput>3</computeroutput>

SELECT EXTRACT(MONTH FROM INTERVAL '2 years 13 months');
<lineannotation>Result: </lineannotation><computeroutput>1</computeroutput>
</screen>
      </listitem>
     </varlistentry>

     <varlistentry>
      <term><literal>quarter</literal></term>
      <listitem>
       <para>
        The quarter of the year (1 - 4) that the day is in (for
        <type>timestamp</type> values only)
       </para>

<screen>
SELECT EXTRACT(QUARTER FROM TIMESTAMP '2001-02-16 20:38:40');
<lineannotation>Result: </lineannotation><computeroutput>1</computeroutput>
</screen>
      </listitem>
     </varlistentry>

     <varlistentry>
      <term><literal>second</literal></term>
      <listitem>
       <para>
        The seconds field, including fractional parts (0 -
        59<footnote><simpara>60 if leap seconds are
        implemented by the operating system</simpara></footnote>)
       </para>

<screen>
SELECT EXTRACT(SECOND FROM TIMESTAMP '2001-02-16 20:38:40');
<lineannotation>Result: </lineannotation><computeroutput>40</computeroutput>

SELECT EXTRACT(SECOND FROM TIME '17:12:28.5');
<lineannotation>Result: </lineannotation><computeroutput>28.5</computeroutput>
</screen>
      </listitem>
     </varlistentry>
     <varlistentry>
      <term><literal>timezone</literal></term>
      <listitem>
       <para>
        The time zone offset from UTC, measured in seconds.  Positive values
        correspond to time zones east of UTC, negative values to
        zones west of UTC.
       </para>
      </listitem>
     </varlistentry>

     <varlistentry>
      <term><literal>timezone_hour</literal></term>
      <listitem>
       <para>
        The hour component of the time zone offset
       </para>
      </listitem>
     </varlistentry>

     <varlistentry>
      <term><literal>timezone_minute</literal></term>
      <listitem>
       <para>
        The minute component of the time zone offset
       </para>
      </listitem>
     </varlistentry>

     <varlistentry>
      <term><literal>week</literal></term>
      <listitem>
       <para>
        The number of the week of the year that the day is in.  By definition
        (<acronym>ISO</acronym> 8601), the first week of a year
        contains January 4 of that year.  (The <acronym>ISO</acronym>-8601
        week starts on Monday.)  In other words, the first Thursday of
        a year is in week 1 of that year. (for <type>timestamp</type> values only)
       </para>
       <para>
        Because of this, it is possible for early January dates to be part of the 
        52nd or 53rd week of the previous year.  For example, <literal>2005-01-01</>
        is part of the 53rd week of year 2004, and <literal>2006-01-01</> is part of 
        the 52nd week of year 2005.
       </para>

<screen>
SELECT EXTRACT(WEEK FROM TIMESTAMP '2001-02-16 20:38:40');
<lineannotation>Result: </lineannotation><computeroutput>7</computeroutput>
</screen>
      </listitem>
     </varlistentry>

     <varlistentry>
      <term><literal>year</literal></term>
      <listitem>
       <para>
        The year field.  Keep in mind there is no <literal>0 AD</>, so subtracting 
        <literal>BC</> years from <literal>AD</> years should be done with care.
       </para>

<screen>
SELECT EXTRACT(YEAR FROM TIMESTAMP '2001-02-16 20:38:40');
<lineannotation>Result: </lineannotation><computeroutput>2001</computeroutput>
</screen>
      </listitem>
     </varlistentry>

    </variablelist>

   </para>

   <para>
    The <function>extract</function> function is primarily intended
    for computational processing.  For formatting date/time values for
    display, see <xref linkend="functions-formatting">.
   </para>

   <para>
    The <function>date_part</function> function is modeled on the traditional
    <productname>Ingres</productname> equivalent to the
    <acronym>SQL</acronym>-standard function <function>extract</function>:
<synopsis>
date_part('<replaceable>field</replaceable>', <replaceable>source</replaceable>)
</synopsis>
    Note that here the <replaceable>field</replaceable> parameter needs to
    be a string value, not a name.  The valid field names for
    <function>date_part</function> are the same as for
    <function>extract</function>.
   </para>

<screen>
SELECT date_part('day', TIMESTAMP '2001-02-16 20:38:40');
<lineannotation>Result: </lineannotation><computeroutput>16</computeroutput>

SELECT date_part('hour', INTERVAL '4 hours 3 minutes');
<lineannotation>Result: </lineannotation><computeroutput>4</computeroutput>
</screen>

  </sect2>

  <sect2 id="functions-datetime-trunc">
   <title><function>date_trunc</function></title>

   <para>
    The function <function>date_trunc</function> is conceptually
    similar to the <function>trunc</function> function for numbers.
   </para>

   <para>
<synopsis>
date_trunc('<replaceable>field</replaceable>', <replaceable>source</replaceable>)
</synopsis>
    <replaceable>source</replaceable> is a value expression of type
    <type>timestamp</type> or <type>interval</>.
    (Values of type <type>date</type> and
    <type>time</type> are cast automatically, to <type>timestamp</type> or
    <type>interval</> respectively.)
    <replaceable>field</replaceable> selects to which precision to
    truncate the input value.  The return value is of type
    <type>timestamp</type> or <type>interval</>
    with all fields that are less significant than the
    selected one set to zero (or one, for day and month).
   </para>

   <para>
    Valid values for <replaceable>field</replaceable> are:
    <simplelist>
     <member><literal>microseconds</literal></member>
     <member><literal>milliseconds</literal></member>
     <member><literal>second</literal></member>
     <member><literal>minute</literal></member>
     <member><literal>hour</literal></member>
     <member><literal>day</literal></member>
     <member><literal>week</literal></member>
     <member><literal>month</literal></member>
     <member><literal>year</literal></member>
     <member><literal>decade</literal></member>
     <member><literal>century</literal></member>
     <member><literal>millennium</literal></member>
    </simplelist>
   </para>

   <para>
    Examples:
<screen>
SELECT date_trunc('hour', TIMESTAMP '2001-02-16 20:38:40');
<lineannotation>Result: </lineannotation><computeroutput>2001-02-16 20:00:00</computeroutput>

SELECT date_trunc('year', TIMESTAMP '2001-02-16 20:38:40');
<lineannotation>Result: </lineannotation><computeroutput>2001-01-01 00:00:00</computeroutput>
</screen>
   </para>
  </sect2>

  <sect2 id="functions-datetime-zoneconvert">
   <title><literal>AT TIME ZONE</literal></title>

   <indexterm>
    <primary>time zone</primary>
    <secondary>conversion</secondary>
   </indexterm>

   <para>
    The <literal>AT TIME ZONE</literal> construct allows conversions
    of time stamps to different time zones.  <xref
    linkend="functions-datetime-zoneconvert-table"> shows its
    variants.
   </para>

    <table id="functions-datetime-zoneconvert-table">
     <title><literal>AT TIME ZONE</literal> Variants</title>
     <tgroup cols="3">
      <thead>
       <row>
        <entry>Expression</entry>
        <entry>Return Type</entry>
        <entry>Description</entry>
       </row>
      </thead>

      <tbody>
       <row>
        <entry>
         <literal><type>timestamp without time zone</type> AT TIME ZONE <replaceable>zone</></literal>
        </entry>
        <entry><type>timestamp with time zone</type></entry>
        <entry>Convert local time in given time zone to UTC</entry>
       </row>

       <row>
        <entry>
         <literal><type>timestamp with time zone</type> AT TIME ZONE <replaceable>zone</></literal>
        </entry>
        <entry><type>timestamp without time zone</type></entry>
        <entry>Convert UTC to local time in given time zone</entry>
       </row>

       <row>
        <entry>
         <literal><type>time with time zone</type> AT TIME ZONE <replaceable>zone</></literal>
        </entry>
        <entry><type>time with time zone</type></entry>
        <entry>Convert local time across time zones</entry>
       </row>
      </tbody>
     </tgroup>
    </table>

   <para>
    In these expressions, the desired time zone <replaceable>zone</> can be
    specified either as a text string (e.g., <literal>'PST'</literal>)
    or as an interval (e.g., <literal>INTERVAL '-08:00'</literal>).
    In the text case, the available zone names are those shown in
    <xref linkend="datetime-timezone-input-table">.  (It would be useful
    to support the more general names shown in
    <xref linkend="datetime-timezone-set-table">, but this is not yet
    implemented.)
   </para>

   <para>
    Examples (supposing that the local time zone is <literal>PST8PDT</>):
<screen>
SELECT TIMESTAMP '2001-02-16 20:38:40' AT TIME ZONE 'MST';
<lineannotation>Result: </lineannotation><computeroutput>2001-02-16 19:38:40-08</computeroutput>

SELECT TIMESTAMP WITH TIME ZONE '2001-02-16 20:38:40-05' AT TIME ZONE 'MST';
<lineannotation>Result: </lineannotation><computeroutput>2001-02-16 18:38:40</computeroutput>
</screen>
    The first example takes a zone-less time stamp and interprets it as MST time
    (UTC-7) to produce a UTC time stamp, which is then rotated to PST (UTC-8)
    for display.  The second example takes a time stamp specified in EST
    (UTC-5) and converts it to local time in MST (UTC-7).
   </para>

   <para>
    The function <literal><function>timezone</function>(<replaceable>zone</>,
    <replaceable>timestamp</>)</literal> is equivalent to the SQL-conforming construct
    <literal><replaceable>timestamp</> AT TIME ZONE
    <replaceable>zone</></literal>. 
   </para>
  </sect2>

  <sect2 id="functions-datetime-current">
   <title>Current Date/Time</title>

   <indexterm>
    <primary>date</primary>
    <secondary>current</secondary>
   </indexterm>

   <indexterm>
    <primary>time</primary>
    <secondary>current</secondary>
   </indexterm>

   <para>
    The following functions are available to obtain the current date and/or
    time:
<synopsis>
CURRENT_DATE
CURRENT_TIME
CURRENT_TIMESTAMP
CURRENT_TIME ( <replaceable>precision</replaceable> )
CURRENT_TIMESTAMP ( <replaceable>precision</replaceable> )
LOCALTIME
LOCALTIMESTAMP
LOCALTIME ( <replaceable>precision</replaceable> )
LOCALTIMESTAMP ( <replaceable>precision</replaceable> )
</synopsis>
    </para>

    <para>
     <function>CURRENT_TIME</function> and
     <function>CURRENT_TIMESTAMP</function> deliver values with time zone;
     <function>LOCALTIME</function> and
     <function>LOCALTIMESTAMP</function> deliver values without time zone.
    </para>

    <para>
     <function>CURRENT_TIME</function>,
     <function>CURRENT_TIMESTAMP</function>,
     <function>LOCALTIME</function>, and
     <function>LOCALTIMESTAMP</function>
     can optionally be given
     a precision parameter, which causes the result to be rounded
     to that many fractional digits in the seconds field.  Without a precision parameter,
     the result is given to the full available precision.
    </para>

    <note>
     <para>
      Prior to <productname>PostgreSQL</productname> 7.2, the precision
      parameters were unimplemented, and the result was always given
      in integer seconds.
     </para>
    </note>

   <para>
    Some examples:
<screen>
SELECT CURRENT_TIME;
<lineannotation>Result: </lineannotation><computeroutput>14:39:53.662522-05</computeroutput>

SELECT CURRENT_DATE;
<lineannotation>Result: </lineannotation><computeroutput>2001-12-23</computeroutput>

SELECT CURRENT_TIMESTAMP;
<lineannotation>Result: </lineannotation><computeroutput>2001-12-23 14:39:53.662522-05</computeroutput>

SELECT CURRENT_TIMESTAMP(2);
<lineannotation>Result: </lineannotation><computeroutput>2001-12-23 14:39:53.66-05</computeroutput>

SELECT LOCALTIMESTAMP;
<lineannotation>Result: </lineannotation><computeroutput>2001-12-23 14:39:53.662522</computeroutput>
</screen>
   </para>

   <para>
    The function <function>now()</function> is the traditional
    <productname>PostgreSQL</productname> equivalent to
    <function>CURRENT_TIMESTAMP</function>.
   </para>

   <para>
    There is also the function <function>timeofday()</function>, which for historical
    reasons returns a <type>text</type> string rather than a <type>timestamp</type> value:
<screen>
SELECT timeofday();
<lineannotation>Result: </lineannotation><computeroutput>Sat Feb 17 19:07:32.000126 2001 EST</computeroutput>
</screen>
   </para>

   <para>
    It is important to know that
    <function>CURRENT_TIMESTAMP</function> and related functions return
    the start time of the current transaction; their values do not
    change during the transaction. This is considered a feature:
    the intent is to allow a single transaction to have a consistent
    notion of the <quote>current</quote> time, so that multiple
    modifications within the same transaction bear the same
    time stamp. <function>timeofday()</function>
    returns the wall-clock time and does advance during transactions.
   </para>

   <note>
    <para>
     Other database systems may advance these values more
     frequently.
    </para>
   </note>

   <para>
    All the date/time data types also accept the special literal value
    <literal>now</literal> to specify the current date and time.  Thus,
    the following three all return the same result:
<programlisting>
SELECT CURRENT_TIMESTAMP;
SELECT now();
SELECT TIMESTAMP 'now';  -- incorrect for use with DEFAULT
</programlisting>
   </para>

    <tip>
     <para>
      You do not want to use the third form when specifying a <literal>DEFAULT</>
      clause while creating a table.  The system will convert <literal>now</literal>
      to a <type>timestamp</type> as soon as the constant is parsed, so that when
      the default value is needed,
      the time of the table creation would be used!  The first two
      forms will not be evaluated until the default value is used,
      because they are function calls.  Thus they will give the desired
      behavior of defaulting to the time of row insertion.
     </para>
    </tip>
  </sect2>
 </sect1>

  
 <sect1 id="functions-geometry">
  <title>Geometric Functions and Operators</title>

   <para>
    The geometric types <type>point</type>, <type>box</type>,
    <type>lseg</type>, <type>line</type>, <type>path</type>,
    <type>polygon</type>, and <type>circle</type> have a large set of
    native support functions and operators, shown in <xref
    linkend="functions-geometry-op-table">, <xref
    linkend="functions-geometry-func-table">, and <xref
    linkend="functions-geometry-conv-table">.
   </para>

   <table id="functions-geometry-op-table">
     <title>Geometric Operators</title>
     <tgroup cols="3">
      <thead>
       <row>
        <entry>Operator</entry>
        <entry>Description</entry>
        <entry>Example</entry>
       </row>
      </thead>
      <tbody>
       <row>
        <entry> <literal>+</literal> </entry>
        <entry>Translation</entry>
        <entry><literal>box '((0,0),(1,1))' + point '(2.0,0)'</literal></entry>
       </row>
       <row>
        <entry> <literal>-</literal> </entry>
        <entry>Translation</entry>
        <entry><literal>box '((0,0),(1,1))' - point '(2.0,0)'</literal></entry>
       </row>
       <row>
        <entry> <literal>*</literal> </entry>
        <entry>Scaling/rotation</entry>
        <entry><literal>box '((0,0),(1,1))' * point '(2.0,0)'</literal></entry>
       </row>
       <row>
        <entry> <literal>/</literal> </entry>
        <entry>Scaling/rotation</entry>
        <entry><literal>box '((0,0),(2,2))' / point '(2.0,0)'</literal></entry>
       </row>
       <row>
        <entry> <literal>#</literal> </entry>
        <entry>Point or box of intersection</entry>
        <entry><literal>'((1,-1),(-1,1))' # '((1,1),(-1,-1))'</literal></entry>
       </row>
       <row>
        <entry> <literal>#</literal> </entry>
        <entry>Number of points in path or polygon</entry>
        <entry><literal># '((1,0),(0,1),(-1,0))'</literal></entry>
       </row>
       <row>
        <entry> <literal>@-@</literal> </entry>
        <entry>Length or circumference</entry>
        <entry><literal>@-@ path '((0,0),(1,0))'</literal></entry>
       </row>
       <row>
        <entry> <literal>@@</literal> </entry>
        <entry>Center</entry>
        <entry><literal>@@ circle '((0,0),10)'</literal></entry>
       </row>
       <row>
        <entry> <literal>##</literal> </entry>
        <entry>Closest point to first operand on second operand</entry>
        <entry><literal>point '(0,0)' ## lseg '((2,0),(0,2))'</literal></entry>
       </row>
       <row>
        <entry> <literal>&lt;-&gt;</literal> </entry>
        <entry>Distance between</entry>
        <entry><literal>circle '((0,0),1)' &lt;-&gt; circle '((5,0),1)'</literal></entry>
       </row>
       <row>
        <entry> <literal>&amp;&amp;</literal> </entry>
        <entry>Overlaps?</entry>
        <entry><literal>box '((0,0),(1,1))' &amp;&amp; box '((0,0),(2,2))'</literal></entry>
       </row>
       <row>
        <entry> <literal>&amp;&lt;</literal> </entry>
        <entry>Does not extend to the right of?</entry>
        <entry><literal>box '((0,0),(1,1))' &amp;&lt; box '((0,0),(2,2))'</literal></entry>
       </row>
       <row>
        <entry> <literal>&amp;&gt;</literal> </entry>
        <entry>Does not extend to the left of?</entry>
        <entry><literal>box '((0,0),(3,3))' &amp;&gt; box '((0,0),(2,2))'</literal></entry>
       </row>
       <row>
        <entry> <literal>&lt;&lt;</literal> </entry>
        <entry>Is left of?</entry>
        <entry><literal>circle '((0,0),1)' &lt;&lt; circle '((5,0),1)'</literal></entry>
       </row>
       <row>
        <entry> <literal>&gt;&gt;</literal> </entry>
        <entry>Is right of?</entry>
        <entry><literal>circle '((5,0),1)' &gt;&gt; circle '((0,0),1)'</literal></entry>
       </row>
       <row>
        <entry> <literal>&lt;^</literal> </entry>
        <entry>Is below?</entry>
        <entry><literal>circle '((0,0),1)' &lt;^ circle '((0,5),1)'</literal></entry>
       </row>
       <row>
        <entry> <literal>&gt;^</literal> </entry>
        <entry>Is above?</entry>
        <entry><literal>circle '((0,5),1)' &gt;^ circle '((0,0),1)'</literal></entry>
       </row>
       <row>
        <entry> <literal>?#</literal> </entry>
        <entry>Intersects?</entry>
        <entry><literal>lseg '((-1,0),(1,0))' ?# box '((-2,-2),(2,2))'</literal></entry>
       </row>
       <row>
        <entry> <literal>?-</literal> </entry>
        <entry>Is horizontal?</entry>
        <entry><literal>?- lseg '((-1,0),(1,0))'</literal></entry>
       </row>
       <row>
        <entry> <literal>?-</literal> </entry>
        <entry>Are horizontally aligned?</entry>
        <entry><literal>point '(1,0)' ?- point '(0,0)'</literal></entry>
       </row>
       <row>
        <entry> <literal>?|</literal> </entry>
        <entry>Is vertical?</entry>
        <entry><literal>?| lseg '((-1,0),(1,0))'</literal></entry>
       </row>
       <row>
        <entry> <literal>?|</literal> </entry>
        <entry>Are vertically aligned?</entry>
        <entry><literal>point '(0,1)' ?| point '(0,0)'</literal></entry>
       </row>
       <row>
        <entry> <literal>?-|</literal> </entry>
        <entry>Is perpendicular?</entry>
        <entry><literal>lseg '((0,0),(0,1))' ?-| lseg '((0,0),(1,0))'</literal></entry>
       </row>
       <row>
        <entry> <literal>?||</literal> </entry>
        <entry>Are parallel?</entry>
        <entry><literal>lseg '((-1,0),(1,0))' ?|| lseg '((-1,2),(1,2))'</literal></entry>
       </row>
       <row>
        <entry> <literal>~</literal> </entry>
        <entry>Contains?</entry>
        <entry><literal>circle '((0,0),2)' ~ point '(1,1)'</literal></entry>
       </row>
       <row>
        <entry> <literal>@</literal> </entry>
        <entry>Contained in or on?</entry>
        <entry><literal>point '(1,1)' @ circle '((0,0),2)'</literal></entry>
       </row>
       <row>
        <entry> <literal>~=</literal> </entry>
        <entry>Same as?</entry>
        <entry><literal>polygon '((0,0),(1,1))' ~= polygon '((1,1),(0,0))'</literal></entry>
       </row>
      </tbody>
     </tgroup>
   </table>


   <table id="functions-geometry-func-table">
     <title>Geometric Functions</title>
     <tgroup cols="4">
      <thead>
       <row>
        <entry>Function</entry>
        <entry>Return Type</entry>
        <entry>Description</entry>
        <entry>Example</entry>
       </row>
      </thead>
      <tbody>
       <row>
        <entry><literal><function>area</function>(<replaceable>object</>)</literal></entry>
        <entry><type>double precision</type></entry>
        <entry>area</entry>
        <entry><literal>area(box '((0,0),(1,1))')</literal></entry>
       </row>
       <row>
        <entry><literal><function>box_intersect</function>(<type>box</>, <type>box</>)</literal></entry>
        <entry><type>box</type></entry>
        <entry>intersection box</entry>
        <entry><literal>box_intersect(box '((0,0),(1,1))',box '((0.5,0.5),(2,2))')</literal></entry>
       </row>
       <row>
        <entry><literal><function>center</function>(<replaceable>object</>)</literal></entry>
        <entry><type>point</type></entry>
        <entry>center</entry>
        <entry><literal>center(box '((0,0),(1,2))')</literal></entry>
       </row>
       <row>
        <entry><literal><function>diameter</function>(<type>circle</>)</literal></entry>
        <entry><type>double precision</type></entry>
        <entry>diameter of circle</entry>
        <entry><literal>diameter(circle '((0,0),2.0)')</literal></entry>
       </row>
       <row>
        <entry><literal><function>height</function>(<type>box</>)</literal></entry>
        <entry><type>double precision</type></entry>
        <entry>vertical size of box</entry>
        <entry><literal>height(box '((0,0),(1,1))')</literal></entry>
       </row>
       <row>
        <entry><literal><function>isclosed</function>(<type>path</>)</literal></entry>
        <entry><type>boolean</type></entry>
        <entry>a closed path?</entry>
        <entry><literal>isclosed(path '((0,0),(1,1),(2,0))')</literal></entry>
       </row>
       <row>
        <entry><literal><function>isopen</function>(<type>path</>)</literal></entry>
        <entry><type>boolean</type></entry>
        <entry>an open path?</entry>
        <entry><literal>isopen(path '[(0,0),(1,1),(2,0)]')</literal></entry>
       </row>
       <row>
        <entry><literal><function>length</function>(<replaceable>object</>)</literal></entry>
        <entry><type>double precision</type></entry>
        <entry>length</entry>
        <entry><literal>length(path '((-1,0),(1,0))')</literal></entry>
       </row>
       <row>
        <entry><literal><function>npoints</function>(<type>path</>)</literal></entry>
        <entry><type>integer</type></entry>
        <entry>number of points</entry>
        <entry><literal>npoints(path '[(0,0),(1,1),(2,0)]')</literal></entry>
       </row>
       <row>
        <entry><literal><function>npoints</function>(<type>polygon</>)</literal></entry>
        <entry><type>integer</type></entry>
        <entry>number of points</entry>
        <entry><literal>npoints(polygon '((1,1),(0,0))')</literal></entry>
       </row>
       <row>
        <entry><literal><function>pclose</function>(<type>path</>)</literal></entry>
        <entry><type>path</type></entry>
        <entry>convert path to closed</entry>
        <entry><literal>pclose(path '[(0,0),(1,1),(2,0)]')</literal></entry>
       </row>
<![IGNORE[
<!-- Not defined by this name. Implements the intersection operator '#' -->
       <row>
        <entry><literal><function>point</function>(<type>lseg</>, <type>lseg</>)</literal></entry>
        <entry><type>point</type></entry>
        <entry>intersection</entry>
        <entry><literal>point(lseg '((-1,0),(1,0))',lseg '((-2,-2),(2,2))')</literal></entry>
       </row>
]]>
       <row>
        <entry><literal><function>popen</function>(<type>path</>)</literal></entry>
        <entry><type>path</type></entry>
        <entry>convert path to open</entry>
        <entry><literal>popen(path '((0,0),(1,1),(2,0))')</literal></entry>
       </row>
       <row>
        <entry><literal><function>radius</function>(<type>circle</type>)</literal></entry>
        <entry><type>double precision</type></entry>
        <entry>radius of circle</entry>
        <entry><literal>radius(circle '((0,0),2.0)')</literal></entry>
       </row>
       <row>
        <entry><literal><function>width</function>(<type>box</>)</literal></entry>
        <entry><type>double precision</type></entry>
        <entry>horizontal size of box</entry>
        <entry><literal>width(box '((0,0),(1,1))')</literal></entry>
       </row>
      </tbody>
     </tgroup>
   </table>


   <table id="functions-geometry-conv-table">
     <title>Geometric Type Conversion Functions</title>
     <tgroup cols="4">
      <thead>
       <row>
        <entry>Function</entry>
        <entry>Return Type</entry>
        <entry>Description</entry>
        <entry>Example</entry>
       </row>
      </thead>
      <tbody>
       <row>
        <entry><literal><function>box</function>(<type>circle</type>)</literal></entry>
        <entry><type>box</type></entry>
        <entry>circle to box</entry>
        <entry><literal>box(circle '((0,0),2.0)')</literal></entry>
       </row>
       <row>
        <entry><literal><function>box</function>(<type>point</type>, <type>point</type>)</literal></entry>
        <entry><type>box</type></entry>
        <entry>points to box</entry>
        <entry><literal>box(point '(0,0)', point '(1,1)')</literal></entry>
       </row>
       <row>
        <entry><literal><function>box</function>(<type>polygon</type>)</literal></entry>
        <entry><type>box</type></entry>
        <entry>polygon to box</entry>
        <entry><literal>box(polygon '((0,0),(1,1),(2,0))')</literal></entry>
       </row>
       <row>
        <entry><literal><function>circle</function>(<type>box</type>)</literal></entry>
        <entry><type>circle</type></entry>
        <entry>box to circle</entry>
        <entry><literal>circle(box '((0,0),(1,1))')</literal></entry>
       </row>
       <row>
        <entry><literal><function>circle</function>(<type>point</type>, <type>double precision</type>)</literal></entry>
        <entry><type>circle</type></entry>
        <entry>center and radius to circle</entry>
        <entry><literal>circle(point '(0,0)', 2.0)</literal></entry>
       </row>
       <row>
        <entry><literal><function>lseg</function>(<type>box</type>)</literal></entry>
        <entry><type>lseg</type></entry>
        <entry>box diagonal to line segment</entry>
        <entry><literal>lseg(box '((-1,0),(1,0))')</literal></entry>
       </row>
       <row>
        <entry><literal><function>lseg</function>(<type>point</type>, <type>point</type>)</literal></entry>
        <entry><type>lseg</type></entry>
        <entry>points to line segment</entry>
        <entry><literal>lseg(point '(-1,0)', point '(1,0)')</literal></entry>
       </row>
       <row>
        <entry><literal><function>path</function>(<type>polygon</type>)</literal></entry>
        <entry><type>point</type></entry>
        <entry>polygon to path</entry>
        <entry><literal>path(polygon '((0,0),(1,1),(2,0))')</literal></entry>
       </row>
       <row>
        <entry><literal><function>point</function>(<type>double
         precision</type>, <type>double precision</type>)</literal></entry>
        <entry><type>point</type></entry>
        <entry>construct point</entry>
        <entry><literal>point(23.4, -44.5)</literal></entry>
       </row>
       <row>
        <entry><literal><function>point</function>(<type>box</type>)</literal></entry>
        <entry><type>point</type></entry>
        <entry>center of box</entry>
        <entry><literal>point(box '((-1,0),(1,0))')</literal></entry>
       </row>
       <row>
        <entry><literal><function>point</function>(<type>circle</type>)</literal></entry>
        <entry><type>point</type></entry>
        <entry>center of circle</entry>
        <entry><literal>point(circle '((0,0),2.0)')</literal></entry>
       </row>
       <row>
        <entry><literal><function>point</function>(<type>lseg</type>)</literal></entry>
        <entry><type>point</type></entry>
        <entry>center of lseg</entry>
        <entry><literal>point(lseg '((-1,0),(1,0))')</literal></entry>
       </row>
       <row>
        <entry><literal><function>point</function>(<type>lseg</type>, <type>lseg</type>)</literal></entry>
        <entry><type>point</type></entry>
        <entry>intersection</entry>
        <entry><literal>point(lseg '((-1,0),(1,0))', lseg '((-2,-2),(2,2))')</literal></entry>
       </row>
       <row>
        <entry><literal><function>point</function>(<type>polygon</type>)</literal></entry>
        <entry><type>point</type></entry>
        <entry>center of polygon</entry>
        <entry><literal>point(polygon '((0,0),(1,1),(2,0))')</literal></entry>
       </row>
       <row>
        <entry><literal><function>polygon</function>(<type>box</type>)</literal></entry>
        <entry><type>polygon</type></entry>
        <entry>box to 4-point polygon</entry>
        <entry><literal>polygon(box '((0,0),(1,1))')</literal></entry>
       </row>
       <row>
        <entry><literal><function>polygon</function>(<type>circle</type>)</literal></entry>
        <entry><type>polygon</type></entry>
        <entry>circle to 12-point polygon</entry>
        <entry><literal>polygon(circle '((0,0),2.0)')</literal></entry>
       </row>
       <row>
        <entry><literal><function>polygon</function>(<replaceable class="parameter">npts</replaceable>, <type>circle</type>)</literal></entry>
        <entry><type>polygon</type></entry>
        <entry>circle to <replaceable class="parameter">npts</replaceable>-point polygon</entry>
        <entry><literal>polygon(12, circle '((0,0),2.0)')</literal></entry>
       </row>
       <row>
        <entry><literal><function>polygon</function>(<type>path</type>)</literal></entry>
        <entry><type>polygon</type></entry>
        <entry>path to polygon</entry>
        <entry><literal>polygon(path '((0,0),(1,1),(2,0))')</literal></entry>
       </row>
      </tbody>
     </tgroup>
   </table>

    <para>
     It is possible to access the two component numbers of a <type>point</>
     as though it were an array with indices 0 and 1.  For example, if
     <literal>t.p</> is a <type>point</> column then
     <literal>SELECT p[0] FROM t</> retrieves the X coordinate and
     <literal>UPDATE t SET p[1] = ...</> changes the Y coordinate.
     In the same way, a value of type <type>box</> or <type>lseg</> may be treated
     as an array of two <type>point</> values.
    </para>

    <para>
     The <function>area</function> function works for the types
     <type>box</type>, <type>circle</type>, and <type>path</type>.
     The <function>area</function> function only works on the
     <type>path</type> data type if the points in the
     <type>path</type> are non-intersecting.  For example, the
     <type>path</type>
     <literal>'((0,0),(0,1),(2,1),(2,2),(1,2),(1,0),(0,0))'::PATH</literal>
     won't work, however, the following visually identical
     <type>path</type>
     <literal>'((0,0),(0,1),(1,1),(1,2),(2,2),(2,1),(1,1),(1,0),(0,0))'::PATH</literal>
     will work.  If the concept of an intersecting versus
     non-intersecting <type>path</type> is confusing, draw both of the
     above <type>path</type>s side by side on a piece of graph paper.
    </para>

  </sect1>


 <sect1 id="functions-net">
  <title>Network Address Functions and Operators</title>

  <para>
   <xref linkend="cidr-inet-operators-table"> shows the operators
   available for the <type>cidr</type> and <type>inet</type> types.
   The operators <literal>&lt;&lt;</literal>,
   <literal>&lt;&lt;=</literal>, <literal>&gt;&gt;</literal>, and
   <literal>&gt;&gt;=</literal> test for subnet inclusion.  They
   consider only the network parts of the two addresses, ignoring any
   host part, and determine whether one network part is identical to
   or a subnet of the other.
  </para>

    <table id="cidr-inet-operators-table">
     <title><type>cidr</type> and <type>inet</type> Operators</title>
     <tgroup cols="3">
      <thead>
       <row>
        <entry>Operator</entry>
        <entry>Description</entry>
        <entry>Example</entry>
       </row>
      </thead>
      <tbody>
       <row>
        <entry> <literal>&lt;</literal> </entry>
        <entry>is less than</entry>
        <entry><literal>inet '192.168.1.5' &lt; inet '192.168.1.6'</literal></entry>
       </row>
       <row>
        <entry> <literal>&lt;=</literal> </entry>
        <entry>is less than or equal</entry>
        <entry><literal>inet '192.168.1.5' &lt;= inet '192.168.1.5'</literal></entry>
       </row>
       <row>
        <entry> <literal>=</literal> </entry>
        <entry>equals</entry>
        <entry><literal>inet '192.168.1.5' = inet '192.168.1.5'</literal></entry>
       </row>
       <row>
        <entry> <literal>&gt;=</literal> </entry>
        <entry>is greater or equal</entry>
        <entry><literal>inet '192.168.1.5' &gt;= inet '192.168.1.5'</literal></entry>
       </row>
       <row>
        <entry> <literal>&gt;</literal> </entry>
        <entry>is greater than</entry>
        <entry><literal>inet '192.168.1.5' &gt; inet '192.168.1.4'</literal></entry>
       </row>
       <row>
        <entry> <literal>&lt;&gt;</literal> </entry>
        <entry>is not equal</entry>
        <entry><literal>inet '192.168.1.5' &lt;&gt; inet '192.168.1.4'</literal></entry>
       </row>
       <row>
        <entry> <literal>&lt;&lt;</literal> </entry>
        <entry>is contained within</entry>
        <entry><literal>inet '192.168.1.5' &lt;&lt; inet '192.168.1/24'</literal></entry>
       </row>
       <row>
        <entry> <literal>&lt;&lt;=</literal> </entry>
        <entry>is contained within or equals</entry>
        <entry><literal>inet '192.168.1/24' &lt;&lt;= inet '192.168.1/24'</literal></entry>
       </row>
       <row>
        <entry> <literal>&gt;&gt;</literal> </entry>
        <entry>contains</entry>
        <entry><literal>inet '192.168.1/24' &gt;&gt; inet '192.168.1.5'</literal></entry>
       </row>
       <row>
        <entry> <literal>&gt;&gt;=</literal> </entry>
        <entry>contains or equals</entry>
        <entry><literal>inet '192.168.1/24' &gt;&gt;= inet '192.168.1/24'</literal></entry>
       </row>
      </tbody>
     </tgroup>
    </table>

  <para>
   <xref linkend="cidr-inet-functions-table"> shows the functions
   available for use with the <type>cidr</type> and <type>inet</type>
   types.  The <function>host</function>,
   <function>text</function>, and <function>abbrev</function>
   functions are primarily intended to offer alternative display
   formats. You can cast a text value to <type>inet</> using normal casting
   syntax: <literal>inet(<replaceable>expression</>)</literal> or
   <literal><replaceable>colname</>::inet</literal>.
  </para>

    <table id="cidr-inet-functions-table">
     <title><type>cidr</type> and <type>inet</type> Functions</title>
     <tgroup cols="5">
      <thead>
       <row>
        <entry>Function</entry>
        <entry>Return Type</entry>
        <entry>Description</entry>
        <entry>Example</entry>
        <entry>Result</entry>
       </row>
      </thead>
      <tbody>
       <row>
        <entry><literal><function>broadcast</function>(<type>inet</type>)</literal></entry>
        <entry><type>inet</type></entry>
        <entry>broadcast address for network</entry>
        <entry><literal>broadcast('192.168.1.5/24')</literal></entry>
        <entry><literal>192.168.1.255/24</literal></entry>
       </row>
       <row>
        <entry><literal><function>host</function>(<type>inet</type>)</literal></entry>
        <entry><type>text</type></entry>
        <entry>extract IP address as text</entry>
        <entry><literal>host('192.168.1.5/24')</literal></entry>
        <entry><literal>192.168.1.5</literal></entry>
       </row>
       <row>
        <entry><literal><function>masklen</function>(<type>inet</type>)</literal></entry>
        <entry><type>integer</type></entry>
        <entry>extract netmask length</entry>
        <entry><literal>masklen('192.168.1.5/24')</literal></entry>
        <entry><literal>24</literal></entry>
       </row>
       <row>
        <entry><literal><function>set_masklen</function>(<type>inet</type>, <type>integer</type>)</literal></entry>
        <entry><type>inet</type></entry>
        <entry>set netmask length for <type>inet</type> value</entry>
        <entry><literal>set_masklen('192.168.1.5/24', 16)</literal></entry>
        <entry><literal>192.168.1.5/16</literal></entry>
       </row>
       <row>
        <entry><literal><function>netmask</function>(<type>inet</type>)</literal></entry>
        <entry><type>inet</type></entry>
        <entry>construct netmask for network</entry>
        <entry><literal>netmask('192.168.1.5/24')</literal></entry>
        <entry><literal>255.255.255.0</literal></entry>
       </row>
       <row>
        <entry><literal><function>hostmask</function>(<type>inet</type>)</literal></entry>
        <entry><type>inet</type></entry>
        <entry>construct host mask for network</entry>
        <entry><literal>hostmask('192.168.23.20/30')</literal></entry>
        <entry><literal>0.0.0.3</literal></entry>
       </row>
       <row>
        <entry><literal><function>network</function>(<type>inet</type>)</literal></entry>
        <entry><type>cidr</type></entry>
        <entry>extract network part of address</entry>
        <entry><literal>network('192.168.1.5/24')</literal></entry>
        <entry><literal>192.168.1.0/24</literal></entry>
       </row>
       <row>
        <entry><literal><function>text</function>(<type>inet</type>)</literal></entry>
        <entry><type>text</type></entry>
        <entry>extract IP address and netmask length as text</entry>
        <entry><literal>text(inet '192.168.1.5')</literal></entry>
        <entry><literal>192.168.1.5/32</literal></entry>
       </row>
       <row>
        <entry><literal><function>abbrev</function>(<type>inet</type>)</literal></entry>
        <entry><type>text</type></entry>
        <entry>abbreviated display format as text</entry>
        <entry><literal>abbrev(cidr '10.1.0.0/16')</literal></entry>
        <entry><literal>10.1/16</literal></entry>
       </row>
       <row>
    <entry><literal><function>family</function>(<type>inet</type>)</literal></entry>
    <entry><type>integer</type></entry>
    <entry>extract family of address; <literal>4</literal> for IPv4,
    <literal>6</literal> for IPv6</entry>
    <entry><literal>family('::1')</literal></entry>
    <entry><literal>6</literal></entry>
       </row>
      </tbody>
     </tgroup>
    </table>

  <para>
   <xref linkend="macaddr-functions-table"> shows the functions
   available for use with the <type>macaddr</type> type.  The function
   <literal><function>trunc</function>(<type>macaddr</type>)</literal> returns a MAC
   address with the last 3 bytes set to zero.  This can be used to
   associate the remaining prefix with a manufacturer.  The directory
   <filename>contrib/mac</filename> in the source distribution
   contains some utilities to create and maintain such an association
   table.
  </para>

    <table id="macaddr-functions-table">
     <title><type>macaddr</type> Functions</title>
     <tgroup cols="5">
      <thead>
       <row>
        <entry>Function</entry>
        <entry>Return Type</entry>
        <entry>Description</entry>
        <entry>Example</entry>
        <entry>Result</entry>
       </row>
      </thead>
      <tbody>
       <row>
        <entry><literal><function>trunc</function>(<type>macaddr</type>)</literal></entry>
        <entry><type>macaddr</type></entry>
        <entry>set last 3 bytes to zero</entry>
        <entry><literal>trunc(macaddr '12:34:56:78:90:ab')</literal></entry>
        <entry><literal>12:34:56:00:00:00</literal></entry>
       </row>
      </tbody>
     </tgroup>
    </table>

   <para>
    The <type>macaddr</type> type also supports the standard relational
    operators (<literal>&gt;</literal>, <literal>&lt;=</literal>, etc.) for
    lexicographical ordering.
   </para>

  </sect1>


 <sect1 id="functions-sequence">
  <title>Sequence Manipulation Functions</title>

  <indexterm>
   <primary>sequence</primary>
  </indexterm>
  <indexterm>
   <primary>nextval</primary>
  </indexterm>
  <indexterm>
   <primary>currval</primary>
  </indexterm>
  <indexterm>
   <primary>lastval</primary>
  </indexterm>
  <indexterm>
   <primary>setval</primary>
  </indexterm>

  <para>
   This section describes <productname>PostgreSQL</productname>'s functions
   for operating on <firstterm>sequence objects</firstterm>.
   Sequence objects (also called sequence generators or
   just sequences) are special single-row tables created with
   <command>CREATE SEQUENCE</command>.  A sequence object is usually used to
   generate unique identifiers for rows of a table.  The sequence functions,
   listed in <xref linkend="functions-sequence-table">,
   provide simple, multiuser-safe methods for obtaining successive
   sequence values from sequence objects.
  </para>

   <table id="functions-sequence-table">
    <title>Sequence Functions</title>
    <tgroup cols="3">
     <thead>
      <row><entry>Function</entry> <entry>Return Type</entry> <entry>Description</entry></row>
     </thead>

     <tbody>
      <row>
        <entry><literal><function>nextval</function>(<type>text</type>)</literal></entry>
        <entry><type>bigint</type></entry>
        <entry>Advance sequence and return new value</entry>
      </row>
      <row>
        <entry><literal><function>currval</function>(<type>text</type>)</literal></entry>
        <entry><type>bigint</type></entry>
        <entry>Return value most recently obtained with
        <function>nextval</function> for specified sequence</entry>
      </row>
      <row>
        <entry><literal><function>lastval</function>()</literal></entry>
        <entry><type>bigint</type></entry>
        <entry>Return value most recently obtained with <function>nextval</function></entry>
      </row>
      <row>
        <entry><literal><function>setval</function>(<type>text</type>, <type>bigint</type>)</literal></entry>
        <entry><type>bigint</type></entry>
        <entry>Set sequence's current value</entry>
      </row>
      <row>
        <entry><literal><function>setval</function>(<type>text</type>, <type>bigint</type>, <type>boolean</type>)</literal></entry>
        <entry><type>bigint</type></entry>
        <entry>Set sequence's current value and <literal>is_called</literal> flag</entry>
      </row>
     </tbody>
    </tgroup>
   </table>

  <para>
   For largely historical reasons, the sequence to be operated on by a
   sequence-function call is specified by a text-string argument.  To
   achieve some compatibility with the handling of ordinary
   <acronym>SQL</acronym> names, the sequence functions convert their
   argument to lowercase unless the string is double-quoted.  Thus
<programlisting>
nextval('foo')      <lineannotation>operates on sequence <literal>foo</literal></>
nextval('FOO')      <lineannotation>operates on sequence <literal>foo</literal></>
nextval('"Foo"')    <lineannotation>operates on sequence <literal>Foo</literal></>
</programlisting>
   The sequence name can be schema-qualified if necessary:
<programlisting>
nextval('myschema.foo')     <lineannotation>operates on <literal>myschema.foo</literal></>
nextval('"myschema".foo')   <lineannotation>same as above</lineannotation>
nextval('foo')              <lineannotation>searches search path for <literal>foo</literal></>
</programlisting>
   Of course, the text argument can be the result of an expression,
   not only a simple literal, which is occasionally useful.
  </para>

  <para>
   The available sequence functions are:

    <variablelist>
     <varlistentry>
      <term><function>nextval</function></term>
      <listitem>
       <para>
        Advance the sequence object to its next value and return that
        value.  This is done atomically: even if multiple sessions
        execute <function>nextval</function> concurrently, each will safely receive
        a distinct sequence value.
       </para>
      </listitem>
     </varlistentry>

     <varlistentry>
      <term><function>currval</function></term>
      <listitem>
       <para>
        Return the value most recently obtained by <function>nextval</function>
        for this sequence in the current session.  (An error is
        reported if <function>nextval</function> has never been called for this
        sequence in this session.)  Notice that because this is returning
        a session-local value, it gives a predictable answer whether or not
        other sessions have executed <function>nextval</function> since the
        current session did.
       </para>
      </listitem>
     </varlistentry>

     <varlistentry>
      <term><function>lastval</function></term>
      <listitem>
       <para>
        Return the value most recently returned by
        <function>nextval</> in the current session. This function is
        identical to <function>currval</function>, except that instead
        of taking the sequence name as an argument it fetches the
        value of the last sequence that <function>nextval</function>
        was used on in the current session. It is an error to call
        <function>lastval</function> if <function>nextval</function>
        has not yet been called in the current session.
       </para>
      </listitem>
     </varlistentry>

     <varlistentry>
      <term><function>setval</function></term>
      <listitem>
       <para>
        Reset the sequence object's counter value.  The two-parameter
        form sets the sequence's <literal>last_value</literal> field to the specified
        value and sets its <literal>is_called</literal> field to <literal>true</literal>,
        meaning that the next <function>nextval</function> will advance the sequence
        before returning a value.  In the three-parameter form,
        <literal>is_called</literal> may be set either <literal>true</literal> or
        <literal>false</literal>.  If it's set to <literal>false</literal>,
        the next <function>nextval</function> will return exactly the specified
        value, and sequence advancement commences with the following
        <function>nextval</function>.  For example,

<screen>
SELECT setval('foo', 42);           <lineannotation>Next <function>nextval</> will return 43</lineannotation>
SELECT setval('foo', 42, true);     <lineannotation>Same as above</lineannotation>
SELECT setval('foo', 42, false);    <lineannotation>Next <function>nextval</> will return 42</lineannotation>
</screen>

        The result returned by <function>setval</function> is just the value of its
        second argument.
       </para>
      </listitem>
     </varlistentry>
    </variablelist>
  </para>

  <important>
   <para>
    To avoid blocking of concurrent transactions that obtain numbers from the
    same sequence, a <function>nextval</function> operation is never rolled back;
    that is, once a value has been fetched it is considered used, even if the
    transaction that did the <function>nextval</function> later aborts.  This means
    that aborted transactions may leave unused <quote>holes</quote> in the
    sequence of assigned values.  <function>setval</function> operations are never
    rolled back, either.
   </para>
  </important>

  <para>
   If a sequence object has been created with default parameters,
   <function>nextval</function> calls on it will return successive values
   beginning with 1.  Other behaviors can be obtained by using
   special parameters in the <xref linkend="sql-createsequence" endterm="sql-createsequence-title"> command;
   see its command reference page for more information.
  </para>

 </sect1>


 <sect1 id="functions-conditional">
  <title>Conditional Expressions</title>

  <indexterm>
   <primary>CASE</primary>
  </indexterm>

  <indexterm>
   <primary>conditional expression</primary>
  </indexterm>

  <para>
   This section describes the <acronym>SQL</acronym>-compliant conditional expressions
   available in <productname>PostgreSQL</productname>.
  </para>

  <tip>
   <para>
    If your needs go beyond the capabilities of these conditional
    expressions you might want to consider writing a stored procedure
    in a more expressive programming language.
   </para>
  </tip>

  <sect2>
   <title><literal>CASE</></title>

  <para>
   The <acronym>SQL</acronym> <token>CASE</token> expression is a
   generic conditional expression, similar to if/else statements in
   other languages:

<synopsis>
CASE WHEN <replaceable>condition</replaceable> THEN <replaceable>result</replaceable>
     <optional>WHEN ...</optional>
     <optional>ELSE <replaceable>result</replaceable></optional>
END
</synopsis>

   <token>CASE</token> clauses can be used wherever
   an expression is valid.  <replaceable>condition</replaceable> is an
   expression that returns a <type>boolean</type> result.  If the result is true
   then the value of the <token>CASE</token> expression is the
   <replaceable>result</replaceable> that follows the condition.  If the result is false any
   subsequent <token>WHEN</token> clauses are searched in the same
   manner.  If no <token>WHEN</token>
   <replaceable>condition</replaceable> is true then the value of the
   case expression is the <replaceable>result</replaceable> in the
   <token>ELSE</token> clause.  If the <token>ELSE</token> clause is
   omitted and no condition matches, the result is null.
  </para>

   <para>
    An example:
<screen>
SELECT * FROM test;

 a
---
 1
 2
 3


SELECT a,
       CASE WHEN a=1 THEN 'one'
            WHEN a=2 THEN 'two'
            ELSE 'other'
       END
    FROM test;

 a | case
---+-------
 1 | one
 2 | two
 3 | other
</screen>
   </para>

  <para>
   The data types of all the <replaceable>result</replaceable>
   expressions must be convertible to a single output type.
   See <xref linkend="typeconv-union-case"> for more detail.
  </para>

  <para>
   The following <quote>simple</quote> <token>CASE</token> expression is a
   specialized variant of the general form above:

<synopsis>
CASE <replaceable>expression</replaceable>
    WHEN <replaceable>value</replaceable> THEN <replaceable>result</replaceable>
    <optional>WHEN ...</optional>
    <optional>ELSE <replaceable>result</replaceable></optional>
END
</synopsis>

   The
   <replaceable>expression</replaceable> is computed and compared to
   all the <replaceable>value</replaceable> specifications in the
   <token>WHEN</token> clauses until one is found that is equal.  If
   no match is found, the <replaceable>result</replaceable> in the
   <token>ELSE</token> clause (or a null value) is returned.  This is similar
   to the <function>switch</function> statement in C.
  </para>

   <para>
    The example above can be written using the simple
    <token>CASE</token> syntax:
<screen>
SELECT a,
       CASE a WHEN 1 THEN 'one'
              WHEN 2 THEN 'two'
              ELSE 'other'
       END
    FROM test;

 a | case
---+-------
 1 | one
 2 | two
 3 | other
</screen>
   </para>

   <para>
    A <token>CASE</token> expression does not evaluate any subexpressions
    that are not needed to determine the result.  For example, this is a
    possible way of avoiding a division-by-zero failure:
<programlisting>
SELECT ... WHERE CASE WHEN x &lt;&gt; 0 THEN y/x &gt; 1.5 ELSE false END;
</programlisting>
   </para>
  </sect2>

  <sect2>
   <title><literal>COALESCE</></title>

  <indexterm>
   <primary>COALESCE</primary>
  </indexterm>

<synopsis>
<function>COALESCE</function>(<replaceable>value</replaceable> <optional>, ...</optional>)
</synopsis>

  <para>
   The <function>COALESCE</function> function returns the first of its
   arguments that is not null.  Null is returned only if all arguments
   are null.  This is often useful to substitute a
   default value for null values when data is retrieved for display,
   for example:
<programlisting>
SELECT COALESCE(description, short_description, '(none)') ...
</programlisting>
  </para>

   <para>
    Like a <token>CASE</token> expression, <function>COALESCE</function> will
    not evaluate arguments that are not needed to determine the result;
    that is, arguments to the right of the first non-null argument are
    not evaluated.
   </para>
  </sect2>

  <sect2>
   <title><literal>NULLIF</></title>

  <indexterm>
   <primary>NULLIF</primary>
  </indexterm>

<synopsis>
<function>NULLIF</function>(<replaceable>value1</replaceable>, <replaceable>value2</replaceable>)
</synopsis>

  <para>
   The <function>NULLIF</function> function returns a null value if and only
   if <replaceable>value1</replaceable> and
   <replaceable>value2</replaceable> are equal.  Otherwise it returns
   <replaceable>value1</replaceable>.  This can be used to perform the
   inverse operation of the <function>COALESCE</function> example
   given above:
<programlisting>
SELECT NULLIF(value, '(none)') ...
</programlisting>
  </para>

  </sect2>

 </sect1>


 <sect1 id="functions-array">
  <title>Array Functions and Operators</title>

  <para>
   <xref linkend="array-operators-table"> shows the operators
   available for <type>array</type> types.
  </para>

    <table id="array-operators-table">
     <title><type>array</type> Operators</title>
     <tgroup cols="4">
      <thead>
       <row>
        <entry>Operator</entry>
        <entry>Description</entry>
        <entry>Example</entry>
        <entry>Result</entry>
       </row>
      </thead>
      <tbody>
       <row>
        <entry> <literal>=</literal> </entry>
        <entry>equal</entry>
        <entry><literal>ARRAY[1.1,2.1,3.1]::int[] = ARRAY[1,2,3]</literal></entry>
        <entry><literal>t</literal></entry>
       </row>

       <row>
        <entry> <literal>&lt;&gt;</literal> </entry>
        <entry>not equal</entry>
        <entry><literal>ARRAY[1,2,3] &lt;&gt; ARRAY[1,2,4]</literal></entry>
        <entry><literal>t</literal></entry>
       </row>

       <row>
        <entry> <literal>&lt;</literal> </entry>
        <entry>less than</entry>
        <entry><literal>ARRAY[1,2,3] &lt; ARRAY[1,2,4]</literal></entry>
        <entry><literal>t</literal></entry>
       </row>

       <row>
        <entry> <literal>&gt;</literal> </entry>
        <entry>greater than</entry>
        <entry><literal>ARRAY[1,4,3] &gt; ARRAY[1,2,4]</literal></entry>
        <entry><literal>t</literal></entry>
       </row>

       <row>
        <entry> <literal>&lt;=</literal> </entry>
        <entry>less than or equal</entry>
        <entry><literal>ARRAY[1,2,3] &lt;= ARRAY[1,2,3]</literal></entry>
        <entry><literal>t</literal></entry>
       </row>

       <row>
        <entry> <literal>&gt;=</literal> </entry>
        <entry>greater than or equal</entry>
        <entry><literal>ARRAY[1,4,3] &gt;= ARRAY[1,4,3]</literal></entry>
        <entry><literal>t</literal></entry>
       </row>

       <row>
        <entry> <literal>||</literal> </entry>
        <entry>array-to-array concatenation</entry>
        <entry><literal>ARRAY[1,2,3] || ARRAY[4,5,6]</literal></entry>
        <entry><literal>{1,2,3,4,5,6}</literal></entry>
       </row>

       <row>
        <entry> <literal>||</literal> </entry>
        <entry>array-to-array concatenation</entry>
        <entry><literal>ARRAY[1,2,3] || ARRAY[[4,5,6],[7,8,9]]</literal></entry>
        <entry><literal>{{1,2,3},{4,5,6},{7,8,9}}</literal></entry>
       </row>

       <row>
        <entry> <literal>||</literal> </entry>
        <entry>element-to-array concatenation</entry>
        <entry><literal>3 || ARRAY[4,5,6]</literal></entry>
        <entry><literal>{3,4,5,6}</literal></entry>
       </row>

       <row>
        <entry> <literal>||</literal> </entry>
        <entry>array-to-element concatenation</entry>
        <entry><literal>ARRAY[4,5,6] || 7</literal></entry>
        <entry><literal>{4,5,6,7}</literal></entry>
       </row>
      </tbody>
     </tgroup>
    </table>

  <para>
   See <xref linkend="arrays"> for more details about array operator
   behavior.
  </para>

  <para>
   <xref linkend="array-functions-table"> shows the functions
   available for use with array types. See <xref linkend="arrays">
   for more discussion and examples of the use of these functions.
  </para>

    <table id="array-functions-table">
     <title><type>array</type> Functions</title>
     <tgroup cols="5">
      <thead>
       <row>
        <entry>Function</entry>
        <entry>Return Type</entry>
        <entry>Description</entry>
        <entry>Example</entry>
        <entry>Result</entry>
       </row>
      </thead>
      <tbody>
       <row>
        <entry>
     <literal>
      <function>array_cat</function>
      (<type>anyarray</type>, <type>anyarray</type>)
     </literal>
    </entry>
        <entry><type>anyarray</type></entry>
        <entry>concatenate two arrays</entry>
        <entry><literal>array_cat(ARRAY[1,2,3], ARRAY[4,5])</literal></entry>
        <entry><literal>{1,2,3,4,5}</literal></entry>
       </row>
       <row>
        <entry>
     <literal>
      <function>array_append</function>
      (<type>anyarray</type>, <type>anyelement</type>)
     </literal>
    </entry>
        <entry><type>anyarray</type></entry>
        <entry>append an element to the end of an array</entry>
        <entry><literal>array_append(ARRAY[1,2], 3)</literal></entry>
        <entry><literal>{1,2,3}</literal></entry>
       </row>
       <row>
        <entry>
     <literal>
      <function>array_prepend</function>
      (<type>anyelement</type>, <type>anyarray</type>)
     </literal>
    </entry>
        <entry><type>anyarray</type></entry>
        <entry>append an element to the beginning of an array</entry>
        <entry><literal>array_prepend(1, ARRAY[2,3])</literal></entry>
        <entry><literal>{1,2,3}</literal></entry>
       </row>
       <row>
        <entry>
     <literal>
      <function>array_dims</function>
      (<type>anyarray</type>)
     </literal>
    </entry>
        <entry><type>text</type></entry>
        <entry>returns a text representation of array's dimensions</entry>
        <entry><literal>array_dims(ARRAY[[1,2,3], [4,5,6]])</literal></entry>
        <entry><literal>[1:2][1:3]</literal></entry>
       </row>
       <row>
        <entry>
     <literal>
      <function>array_lower</function>
      (<type>anyarray</type>, <type>integer</type>)
     </literal>
    </entry>
        <entry><type>integer</type></entry>
        <entry>returns lower bound of the requested array dimension</entry>
        <entry><literal>array_lower(array_prepend(0, ARRAY[1,2,3]), 1)</literal></entry>
        <entry><literal>0</literal></entry>
       </row>
       <row>
        <entry>
     <literal>
      <function>array_upper</function>
      (<type>anyarray</type>, <type>integer</type>)
     </literal>
    </entry>
        <entry><type>integer</type></entry>
        <entry>returns upper bound of the requested array dimension</entry>
        <entry><literal>array_upper(ARRAY[1,2,3,4], 1)</literal></entry>
        <entry><literal>4</literal></entry>
       </row>
       <row>
        <entry>
     <literal>
      <function>array_to_string</function>
      (<type>anyarray</type>, <type>text</type>)
     </literal>
    </entry>
        <entry><type>text</type></entry>
        <entry>concatenates array elements using provided delimiter</entry>
        <entry><literal>array_to_string(ARRAY[1, 2, 3], '~^~')</literal></entry>
        <entry><literal>1~^~2~^~3</literal></entry>
       </row>
       <row>
        <entry>
     <literal>
      <function>string_to_array</function>
      (<type>text</type>, <type>text</type>)
     </literal>
    </entry>
        <entry><type>text[]</type></entry>
        <entry>splits string into array elements using provided delimiter</entry>
        <entry><literal>string_to_array('xx~^~yy~^~zz', '~^~')</literal></entry>
        <entry><literal>{xx,yy,zz}</literal></entry>
       </row>
      </tbody>
     </tgroup>
    </table>
  </sect1>

 <sect1 id="functions-aggregate">
  <title>Aggregate Functions</title>

  <indexterm zone="functions-aggregate">
   <primary>aggregate function</primary>
   <secondary>built-in</secondary>
  </indexterm>

  <para>
   <firstterm>Aggregate functions</firstterm> compute a single result
   value from a set of input values.  <xref
   linkend="functions-aggregate-table"> shows the built-in aggregate
   functions.  The special syntax considerations for aggregate
   functions are explained in <xref linkend="syntax-aggregates">.
   Consult <xref linkend="tutorial-agg"> for additional introductory
   information.
  </para>

  <table id="functions-aggregate-table">
   <title>Aggregate Functions</title>

   <tgroup cols="4">
    <thead>
     <row>
      <entry>Function</entry>
      <entry>Argument Type</entry>
      <entry>Return Type</entry>
      <entry>Description</entry>
     </row>
    </thead>

    <tbody>
     <row>
      <entry>
       <indexterm>
        <primary>average</primary>
       </indexterm>
       <function>avg(<replaceable class="parameter">expression</replaceable>)</function>
      </entry>
      <entry>
       <type>smallint</type>, <type>integer</type>,
       <type>bigint</type>, <type>real</type>, <type>double
       precision</type>, <type>numeric</type>, or <type>interval</type>
      </entry>
      <entry>
       <type>numeric</type> for any integer type argument,
       <type>double precision</type> for a floating-point argument,
       otherwise the same as the argument data type
      </entry>
      <entry>the average (arithmetic mean) of all input values</entry>
     </row>

     <row>
      <entry>
       <indexterm>
        <primary>bit_and</primary>
       </indexterm>
       <function>bit_and(<replaceable class="parameter">expression</replaceable>)</function>
      </entry>
      <entry>
       <type>smallint</type>, <type>integer</type>, <type>bigint</type>, or
       <type>bit</type>
      </entry>
      <entry>
        same as argument data type
      </entry>
      <entry>the bitwise AND of all non-null input values, or null if none</entry>
     </row>

     <row>
      <entry>
       <indexterm>
        <primary>bit_or</primary>
       </indexterm>
       <function>bit_or(<replaceable class="parameter">expression</replaceable>)</function>
      </entry>
      <entry>
       <type>smallint</type>, <type>integer</type>, <type>bigint</type>, or
       <type>bit</type>
      </entry>
      <entry>
        same as argument data type
      </entry>
      <entry>the bitwise OR of all non-null input values, or null if none</entry>
     </row>

     <row>
      <entry>
       <indexterm>
        <primary>bool_and</primary>
       </indexterm>
       <function>bool_and(<replaceable class="parameter">expression</replaceable>)</function>
      </entry>
      <entry>
       <type>bool</type>
      </entry>
      <entry>
       <type>bool</type>
      </entry>
      <entry>true if all input values are true, otherwise false</entry>
     </row>

     <row>
      <entry>
       <indexterm>
        <primary>bool_or</primary>
       </indexterm>
       <function>bool_or(<replaceable class="parameter">expression</replaceable>)</function>
      </entry>
      <entry>
       <type>bool</type>
      </entry>
      <entry>
       <type>bool</type>
      </entry>
      <entry>true if at least one input value is true, otherwise false</entry>
     </row>

     <row>
      <entry><function>count(*)</function></entry>
      <entry></entry>
      <entry><type>bigint</type></entry>
      <entry>number of input values</entry>
     </row>

     <row>
      <entry><function>count(<replaceable class="parameter">expression</replaceable>)</function></entry>
      <entry>any</entry>
      <entry><type>bigint</type></entry>
      <entry>
       number of input values for which the value of <replaceable
       class="parameter">expression</replaceable> is not null
      </entry>
     </row>

     <row>
      <entry>
       <indexterm>
        <primary>every</primary>
       </indexterm>
       <function>every(<replaceable class="parameter">expression</replaceable>)</function>
      </entry>
      <entry>
       <type>bool</type>
      </entry>
      <entry>
       <type>bool</type>
      </entry>
      <entry>equivalent to <function>bool_and</function></entry>
     </row>

     <row>
      <entry><function>max(<replaceable class="parameter">expression</replaceable>)</function></entry>
      <entry>any array, numeric, string, or date/time type</entry>
      <entry>same as argument type</entry>
      <entry>
       maximum value of <replaceable
       class="parameter">expression</replaceable> across all input
       values
      </entry>
     </row>

     <row>
      <entry><function>min(<replaceable class="parameter">expression</replaceable>)</function></entry>
      <entry>any array, numeric, string, or date/time type</entry>
      <entry>same as argument type</entry>
      <entry>
       minimum value of <replaceable
       class="parameter">expression</replaceable> across all input
       values
      </entry>
     </row>

     <row>
      <entry>
       <indexterm>
        <primary>standard deviation</primary>
       </indexterm>
       <function>stddev(<replaceable class="parameter">expression</replaceable>)</function>
      </entry>
      <entry>
       <type>smallint</type>, <type>integer</type>,
       <type>bigint</type>, <type>real</type>, <type>double
       precision</type>, or <type>numeric</type>
      </entry>
      <entry>
       <type>double precision</type> for floating-point arguments,
       otherwise <type>numeric</type>
      </entry>
      <entry>sample standard deviation of the input values</entry>
     </row>

     <row>
      <entry><function>sum(<replaceable class="parameter">expression</replaceable>)</function></entry>
      <entry>
       <type>smallint</type>, <type>integer</type>,
       <type>bigint</type>, <type>real</type>, <type>double
       precision</type>, <type>numeric</type>, or
       <type>interval</type>
      </entry>
      <entry>
       <type>bigint</type> for <type>smallint</type> or
       <type>integer</type> arguments, <type>numeric</type> for
       <type>bigint</type> arguments, <type>double precision</type>
       for floating-point arguments, otherwise the same as the
       argument data type
      </entry>
      <entry>sum of <replaceable class="parameter">expression</replaceable> across all input values</entry>
     </row>

     <row>
      <entry>
       <indexterm>
        <primary>variance</primary>
       </indexterm>
       <function>variance</function>(<replaceable class="parameter">expression</replaceable>)
      </entry>
      <entry>
       <type>smallint</type>, <type>integer</type>,
       <type>bigint</type>, <type>real</type>, <type>double
       precision</type>, or <type>numeric</type>
      </entry>
      <entry>
       <type>double precision</type> for floating-point arguments,
       otherwise <type>numeric</type>
      </entry>
      <entry>sample variance of the input values (square of the sample standard deviation)</entry>
     </row>

    </tbody>
   </tgroup>
  </table>

  <para>
   It should be noted that except for <function>count</function>,
   these functions return a null value when no rows are selected.  In
   particular, <function>sum</function> of no rows returns null, not
   zero as one might expect.  The <function>coalesce</function> function may be
   used to substitute zero for null when necessary.
  </para>

  <note>
    <indexterm>
      <primary>ANY</primary>
    </indexterm>
    <indexterm>
      <primary>SOME</primary>
    </indexterm>
    <para>
      Boolean aggregates <function>bool_and</function> and 
      <function>bool_or</function> correspond to standard SQL aggregates
      <function>every</function> and <function>any</function> or
      <function>some</function>. 
      As for <function>any</function> and <function>some</function>, 
      it seems that there is an ambiguity built into the standard syntax:
<programlisting>
SELECT b1 = ANY((SELECT b2 FROM t2 ...)) FROM t1 ...;
</programlisting>
      Here <function>ANY</function> can be considered both as leading
      to a subquery or as an aggregate if the select expression returns 1 row.
      Thus the standard name cannot be given to these aggregates.
    </para>
  </note>

  <note>
   <para>
    Users accustomed to working with other SQL database management
    systems may be surprised by the performance of the
    <function>count</function> aggregate when it is applied to the
    entire table. A query like:
<programlisting>
SELECT count(*) FROM sometable;
</programlisting>
    will be executed by <productname>PostgreSQL</productname> using a
    sequential scan of the entire table.
   </para>
  </note>
 </sect1>


 <sect1 id="functions-subquery">
  <title>Subquery Expressions</title>

  <indexterm>
   <primary>EXISTS</primary>
  </indexterm>

  <indexterm>
   <primary>IN</primary>
  </indexterm>

  <indexterm>
   <primary>NOT IN</primary>
  </indexterm>

  <indexterm>
   <primary>ANY</primary>
  </indexterm>

  <indexterm>
   <primary>ALL</primary>
  </indexterm>

  <indexterm>
   <primary>SOME</primary>
  </indexterm>

  <indexterm>
   <primary>subquery</primary>
  </indexterm>

  <para>
   This section describes the <acronym>SQL</acronym>-compliant subquery
   expressions available in <productname>PostgreSQL</productname>.
   All of the expression forms documented in this section return
   Boolean (true/false) results.
  </para>

  <sect2>
   <title><literal>EXISTS</literal></title>

<synopsis>
EXISTS ( <replaceable>subquery</replaceable> )
</synopsis>

  <para>
   The argument of <token>EXISTS</token> is an arbitrary <command>SELECT</> statement,
   or <firstterm>subquery</firstterm>.  The
   subquery is evaluated to determine whether it returns any rows.
   If it returns at least one row, the result of <token>EXISTS</token> is
   <quote>true</>; if the subquery returns no rows, the result of <token>EXISTS</token> 
   is <quote>false</>.
  </para>

  <para>
   The subquery can refer to variables from the surrounding query,
   which will act as constants during any one evaluation of the subquery.
  </para>

  <para>
   The subquery will generally only be executed far enough to determine
   whether at least one row is returned, not all the way to completion.
   It is unwise to write a subquery that has any side effects (such as
   calling sequence functions); whether the side effects occur or not
   may be difficult to predict.
  </para>

  <para>
   Since the result depends only on whether any rows are returned,
   and not on the contents of those rows, the output list of the
   subquery is normally uninteresting.  A common coding convention is
   to write all <literal>EXISTS</> tests in the form
   <literal>EXISTS(SELECT 1 WHERE ...)</literal>.  There are exceptions to
   this rule however, such as subqueries that use <token>INTERSECT</token>.
  </para>

  <para>
   This simple example is like an inner join on <literal>col2</>, but
   it produces at most one output row for each <literal>tab1</> row,
   even if there are multiple matching <literal>tab2</> rows:
<screen>
SELECT col1 FROM tab1
    WHERE EXISTS(SELECT 1 FROM tab2 WHERE col2 = tab1.col2);
</screen>
  </para>
  </sect2>

  <sect2>
   <title><literal>IN</literal></title>

<synopsis>
<replaceable>expression</replaceable> IN (<replaceable>subquery</replaceable>)
</synopsis>

  <para>
   The right-hand side is a parenthesized
   subquery, which must return exactly one column.  The left-hand expression
   is evaluated and compared to each row of the subquery result.
   The result of <token>IN</token> is <quote>true</> if any equal subquery row is found.
   The result is <quote>false</> if no equal row is found (including the special
   case where the subquery returns no rows).
  </para>

  <para>
   Note that if the left-hand expression yields null, or if there are
   no equal right-hand values and at least one right-hand row yields
   null, the result of the <token>IN</token> construct will be null, not false.
   This is in accordance with SQL's normal rules for Boolean combinations
   of null values.
  </para>

  <para>
   As with <token>EXISTS</token>, it's unwise to assume that the subquery will
   be evaluated completely.
  </para>

<synopsis>
<replaceable>row_constructor</replaceable> IN (<replaceable>subquery</replaceable>)
</synopsis>

  <para>
   The left-hand side of this form of <token>IN</token> is a row constructor,
   as described in <xref linkend="sql-syntax-row-constructors">.
   The right-hand side is a parenthesized
   subquery, which must return exactly as many columns as there are
   expressions in the left-hand row.  The left-hand expressions are
   evaluated and compared row-wise to each row of the subquery result.
   The result of <token>IN</token> is <quote>true</> if any equal subquery row is found.
   The result is <quote>false</> if no equal row is found (including the special
   case where the subquery returns no rows).
  </para>

  <para>
   As usual, null values in the rows are combined per
   the normal rules of SQL Boolean expressions.  Two rows are considered
   equal if all their corresponding members are non-null and equal; the rows
   are unequal if any corresponding members are non-null and unequal;
   otherwise the result of that row comparison is unknown (null).
   If all the row results are either unequal or null, with at least one null,
   then the result of <token>IN</token> is null.
  </para>
  </sect2>

  <sect2>
   <title><literal>NOT IN</literal></title>

<synopsis>
<replaceable>expression</replaceable> NOT IN (<replaceable>subquery</replaceable>)
</synopsis>

  <para>
   The right-hand side is a parenthesized
   subquery, which must return exactly one column.  The left-hand expression
   is evaluated and compared to each row of the subquery result.
   The result of <token>NOT IN</token> is <quote>true</> if only unequal subquery rows
   are found (including the special case where the subquery returns no rows).
   The result is <quote>false</> if any equal row is found.
  </para>

  <para>
   Note that if the left-hand expression yields null, or if there are
   no equal right-hand values and at least one right-hand row yields
   null, the result of the <token>NOT IN</token> construct will be null, not true.
   This is in accordance with SQL's normal rules for Boolean combinations
   of null values.
  </para>

  <para>
   As with <token>EXISTS</token>, it's unwise to assume that the subquery will
   be evaluated completely.
  </para>

<synopsis>
<replaceable>row_constructor</replaceable> NOT IN (<replaceable>subquery</replaceable>)
</synopsis>

  <para>
   The left-hand side of this form of <token>NOT IN</token> is a row constructor,
   as described in <xref linkend="sql-syntax-row-constructors">.
   The right-hand side is a parenthesized
   subquery, which must return exactly as many columns as there are
   expressions in the left-hand row.  The left-hand expressions are
   evaluated and compared row-wise to each row of the subquery result.
   The result of <token>NOT IN</token> is <quote>true</> if only unequal subquery rows
   are found (including the special case where the subquery returns no rows).
   The result is <quote>false</> if any equal row is found.
  </para>

  <para>
   As usual, null values in the rows are combined per
   the normal rules of SQL Boolean expressions.  Two rows are considered
   equal if all their corresponding members are non-null and equal; the rows
   are unequal if any corresponding members are non-null and unequal;
   otherwise the result of that row comparison is unknown (null).
   If all the row results are either unequal or null, with at least one null,
   then the result of <token>NOT IN</token> is null.
  </para>
  </sect2>

  <sect2>
   <title><literal>ANY</literal>/<literal>SOME</literal></title>

<synopsis>
<replaceable>expression</replaceable> <replaceable>operator</replaceable> ANY (<replaceable>subquery</replaceable>)
<replaceable>expression</replaceable> <replaceable>operator</replaceable> SOME (<replaceable>subquery</replaceable>)
</synopsis>

  <para>
   The right-hand side is a parenthesized
   subquery, which must return exactly one column.  The left-hand expression
   is evaluated and compared to each row of the subquery result using the
   given <replaceable>operator</replaceable>, which must yield a Boolean
   result.
   The result of <token>ANY</token> is <quote>true</> if any true result is obtained.
   The result is <quote>false</> if no true result is found (including the special
   case where the subquery returns no rows).
  </para>

  <para>
   <token>SOME</token> is a synonym for <token>ANY</token>.
   <token>IN</token> is equivalent to <literal>= ANY</literal>.
  </para>

  <para>
   Note that if there are no successes and at least one right-hand row yields
   null for the operator's result, the result of the <token>ANY</token> construct
   will be null, not false.
   This is in accordance with SQL's normal rules for Boolean combinations
   of null values.
  </para>

  <para>
   As with <token>EXISTS</token>, it's unwise to assume that the subquery will
   be evaluated completely.
  </para>

<synopsis>
<replaceable>row_constructor</replaceable> <replaceable>operator</> ANY (<replaceable>subquery</replaceable>)
<replaceable>row_constructor</replaceable> <replaceable>operator</> SOME (<replaceable>subquery</replaceable>)
</synopsis>

  <para>
   The left-hand side of this form of <token>ANY</token> is a row constructor,
   as described in <xref linkend="sql-syntax-row-constructors">.
   The right-hand side is a parenthesized
   subquery, which must return exactly as many columns as there are
   expressions in the left-hand row.  The left-hand expressions are
   evaluated and compared row-wise to each row of the subquery result,
   using the given <replaceable>operator</replaceable>.  Presently,
   only <literal>=</literal> and <literal>&lt;&gt;</literal> operators are allowed
   in row-wise <token>ANY</token> constructs.
   The result of <token>ANY</token> is <quote>true</> if any equal or unequal row is
   found, respectively.
   The result is <quote>false</> if no such row is found (including the special
   case where the subquery returns no rows).
  </para>

  <para>
   As usual, null values in the rows are combined per
   the normal rules of SQL Boolean expressions.  Two rows are considered
   equal if all their corresponding members are non-null and equal; the rows
   are unequal if any corresponding members are non-null and unequal;
   otherwise the result of that row comparison is unknown (null).
   If there is at least one null row result, then the result of <token>ANY</token>
   cannot be false; it will be true or null. 
  </para>
  </sect2>

  <sect2>
   <title><literal>ALL</literal></title>

<synopsis>
<replaceable>expression</replaceable> <replaceable>operator</replaceable> ALL (<replaceable>subquery</replaceable>)
</synopsis>

  <para>
   The right-hand side is a parenthesized
   subquery, which must return exactly one column.  The left-hand expression
   is evaluated and compared to each row of the subquery result using the
   given <replaceable>operator</replaceable>, which must yield a Boolean
   result.
   The result of <token>ALL</token> is <quote>true</> if all rows yield true
   (including the special case where the subquery returns no rows).
   The result is <quote>false</> if any false result is found.
  </para>

  <para>
   <token>NOT IN</token> is equivalent to <literal>&lt;&gt; ALL</literal>.
  </para>

  <para>
   Note that if there are no failures but at least one right-hand row yields
   null for the operator's result, the result of the <token>ALL</token> construct
   will be null, not true.
   This is in accordance with SQL's normal rules for Boolean combinations
   of null values.
  </para>

  <para>
   As with <token>EXISTS</token>, it's unwise to assume that the subquery will
   be evaluated completely.
  </para>

<synopsis>
<replaceable>row_constructor</replaceable> <replaceable>operator</replaceable> ALL (<replaceable>subquery</replaceable>)
</synopsis>

  <para>
   The left-hand side of this form of <token>ALL</token> is a row constructor,
   as described in <xref linkend="sql-syntax-row-constructors">.
   The right-hand side is a parenthesized
   subquery, which must return exactly as many columns as there are
   expressions in the left-hand row.  The left-hand expressions are
   evaluated and compared row-wise to each row of the subquery result,
   using the given <replaceable>operator</replaceable>.  Presently,
   only <literal>=</literal> and <literal>&lt;&gt;</literal> operators are allowed
   in row-wise <token>ALL</token> queries.
   The result of <token>ALL</token> is <quote>true</> if all subquery rows are equal
   or unequal, respectively (including the special
   case where the subquery returns no rows).
   The result is <quote>false</> if any row is found to be unequal or equal,
   respectively.
  </para>

  <para>
   As usual, null values in the rows are combined per
   the normal rules of SQL Boolean expressions.  Two rows are considered
   equal if all their corresponding members are non-null and equal; the rows
   are unequal if any corresponding members are non-null and unequal;
   otherwise the result of that row comparison is unknown (null).
   If there is at least one null row result, then the result of <token>ALL</token>
   cannot be true; it will be false or null. 
  </para>
  </sect2>

  <sect2>
   <title>Row-wise Comparison</title>

   <indexterm zone="functions-subquery">
    <primary>comparison</primary>
    <secondary>subquery result row</secondary>
   </indexterm>

<synopsis>
<replaceable>row_constructor</replaceable> <replaceable>operator</replaceable> (<replaceable>subquery</replaceable>)
</synopsis>

  <para>
   The left-hand side is a row constructor,
   as described in <xref linkend="sql-syntax-row-constructors">.
   The right-hand side is a parenthesized subquery, which must return exactly
   as many columns as there are expressions in the left-hand row. Furthermore,
   the subquery cannot return more than one row.  (If it returns zero rows,
   the result is taken to be null.)  The left-hand side is evaluated and
   compared row-wise to the single subquery result row.
   Presently, only <literal>=</literal> and <literal>&lt;&gt;</literal> operators are allowed
   in row-wise comparisons.
   The result is <quote>true</> if the two rows are equal or unequal, respectively.
  </para>

  <para>
   As usual, null values in the rows are combined per
   the normal rules of SQL Boolean expressions.  Two rows are considered
   equal if all their corresponding members are non-null and equal; the rows
   are unequal if any corresponding members are non-null and unequal;
   otherwise the result of the row comparison is unknown (null).
  </para>
  </sect2>
 </sect1>


 <sect1 id="functions-comparisons">
  <title>Row and Array Comparisons</title>

  <indexterm>
   <primary>IN</primary>
  </indexterm>

  <indexterm>
   <primary>NOT IN</primary>
  </indexterm>

  <indexterm>
   <primary>ANY</primary>
  </indexterm>

  <indexterm>
   <primary>ALL</primary>
  </indexterm>

  <indexterm>
   <primary>SOME</primary>
  </indexterm>

  <indexterm>
   <primary>comparison</primary>
   <secondary>row-wise</secondary>
  </indexterm>

  <indexterm>
   <primary>IS DISTINCT FROM</primary>
  </indexterm>

  <indexterm>
   <primary>IS NULL</primary>
  </indexterm>

  <indexterm>
   <primary>IS NOT NULL</primary>
  </indexterm>

  <para>
   This section describes several specialized constructs for making
   multiple comparisons between groups of values.  These forms are
   syntactically related to the subquery forms of the previous section,
   but do not involve subqueries.
   The forms involving array subexpressions are
   <productname>PostgreSQL</productname> extensions; the rest are
   <acronym>SQL</acronym>-compliant.
   All of the expression forms documented in this section return
   Boolean (true/false) results.
  </para>

  <sect2>
   <title><literal>IN</literal></title>

<synopsis>
<replaceable>expression</replaceable> IN (<replaceable>value</replaceable><optional>, ...</optional>)
</synopsis>

  <para>
   The right-hand side is a parenthesized list
   of scalar expressions.  The result is <quote>true</> if the left-hand expression's
   result is equal to any of the right-hand expressions.  This is a shorthand
   notation for

<synopsis>
<replaceable>expression</replaceable> = <replaceable>value1</replaceable>
OR
<replaceable>expression</replaceable> = <replaceable>value2</replaceable>
OR
...
</synopsis>
  </para>

  <para>
   Note that if the left-hand expression yields null, or if there are
   no equal right-hand values and at least one right-hand expression yields
   null, the result of the <token>IN</token> construct will be null, not false.
   This is in accordance with SQL's normal rules for Boolean combinations
   of null values.
  </para>
  </sect2>

  <sect2>
   <title><literal>NOT IN</literal></title>

<synopsis>
<replaceable>expression</replaceable> NOT IN (<replaceable>value</replaceable><optional>, ...</optional>)
</synopsis>

  <para>
   The right-hand side is a parenthesized list
   of scalar expressions.  The result is <quote>true</quote> if the left-hand expression's
   result is unequal to all of the right-hand expressions.  This is a shorthand
   notation for

<synopsis>
<replaceable>expression</replaceable> &lt;&gt; <replaceable>value1</replaceable>
AND
<replaceable>expression</replaceable> &lt;&gt; <replaceable>value2</replaceable>
AND
...
</synopsis>
  </para>

  <para>
   Note that if the left-hand expression yields null, or if there are
   no equal right-hand values and at least one right-hand expression yields
   null, the result of the <token>NOT IN</token> construct will be null, not true
   as one might naively expect.
   This is in accordance with SQL's normal rules for Boolean combinations
   of null values.
  </para>

  <tip>
  <para>
   <literal>x NOT IN y</literal> is equivalent to <literal>NOT (x IN y)</literal> in all
   cases.  However, null values are much more likely to trip up the novice when
   working with <token>NOT IN</token> than when working with <token>IN</token>.
   It's best to express your condition positively if possible.
  </para>
  </tip>
  </sect2>

  <sect2>
   <title><literal>ANY</literal>/<literal>SOME</literal> (array)</title>

<synopsis>
<replaceable>expression</replaceable> <replaceable>operator</replaceable> ANY (<replaceable>array expression</replaceable>)
<replaceable>expression</replaceable> <replaceable>operator</replaceable> SOME (<replaceable>array expression</replaceable>)
</synopsis>

  <para>
   The right-hand side is a parenthesized expression, which must yield an
   array value.
   The left-hand expression
   is evaluated and compared to each element of the array using the
   given <replaceable>operator</replaceable>, which must yield a Boolean
   result.
   The result of <token>ANY</token> is <quote>true</> if any true result is obtained.
   The result is <quote>false</> if no true result is found (including the special
   case where the array has zero elements).
  </para>

  <para>
   <token>SOME</token> is a synonym for <token>ANY</token>.
  </para>
  </sect2>

  <sect2>
   <title><literal>ALL</literal> (array)</title>

<synopsis>
<replaceable>expression</replaceable> <replaceable>operator</replaceable> ALL (<replaceable>array expression</replaceable>)
</synopsis>

  <para>
   The right-hand side is a parenthesized expression, which must yield an
   array value.
   The left-hand expression
   is evaluated and compared to each element of the array using the
   given <replaceable>operator</replaceable>, which must yield a Boolean
   result.
   The result of <token>ALL</token> is <quote>true</> if all comparisons yield true
   (including the special case where the array has zero elements).
   The result is <quote>false</> if any false result is found.
  </para>
  </sect2>

  <sect2>
   <title>Row-wise Comparison</title>

<synopsis>
<replaceable>row_constructor</replaceable> <replaceable>operator</replaceable> <replaceable>row_constructor</replaceable>
</synopsis>

  <para>
   Each side is a row constructor,
   as described in <xref linkend="sql-syntax-row-constructors">.
   The two row values must have the same number of fields.
   Each side is evaluated and they are compared row-wise.
   Presently, only <literal>=</literal> and <literal>&lt;&gt;</literal> operators are allowed
   in row-wise comparisons.
   The result is <quote>true</> if the two rows are equal or unequal, respectively.
  </para>

  <para>
   As usual, null values in the rows are combined per
   the normal rules of SQL Boolean expressions.  Two rows are considered
   equal if all their corresponding members are non-null and equal; the rows
   are unequal if any corresponding members are non-null and unequal;
   otherwise the result of the row comparison is unknown (null).
  </para>

<synopsis>
<replaceable>row_constructor</replaceable> IS DISTINCT FROM <replaceable>row_constructor</replaceable>
</synopsis>

  <para>
   This construct is similar to a <literal>&lt;&gt;</literal> row comparison,
   but it does not yield null for null inputs.  Instead, any null value is
   considered unequal to (distinct from) any non-null value, and any two
   nulls are considered equal (not distinct).  Thus the result will always
   be either true or false, never null.
  </para>

<synopsis>
<replaceable>row_constructor</replaceable> IS NULL
<replaceable>row_constructor</replaceable> IS NOT NULL
</synopsis>

  <para>
   These constructs test a row value for null or not null.  A row value
   is considered not null if it has at least one field that is not null.
  </para>

  </sect2>
 </sect1>

 <sect1 id="functions-srf">
  <title>Set Returning Functions</title>

  <indexterm zone="functions-srf">
   <primary>set returning functions</primary>
   <secondary>functions</secondary>
  </indexterm>

  <para>
   This section describes functions that possibly return more than one row.
   Currently the only functions in this class are series generating functions,
   as detailed in <xref linkend="functions-srf-series">.
  </para>

  <table id="functions-srf-series">
   <title>Series Generating Functions</title>
   <tgroup cols="4">
    <thead>
     <row>
      <entry>Function</entry>
      <entry>Argument Type</entry>
      <entry>Return Type</entry>
      <entry>Description</entry>
     </row>
    </thead>

    <tbody>
     <row>
      <entry><literal><function>generate_series</function>(<parameter>start</parameter>, <parameter>stop</parameter>)</literal></entry>
      <entry><type>int</type> or <type>bigint</type></entry>
      <entry><type>setof int</type> or <type>setof bigint</type> (same as argument type)</entry>
      <entry>
       Generate a series of values, from <parameter>start</parameter> to <parameter>stop</parameter>
       with a step size of one
      </entry>
     </row>

     <row>
      <entry><literal><function>generate_series</function>(<parameter>start</parameter>, <parameter>stop</parameter>, <parameter>step</parameter>)</literal></entry>
      <entry><type>int</type> or <type>bigint</type></entry>
      <entry><type>setof int</type> or <type>setof bigint</type> (same as argument type)</entry>
      <entry>
       Generate a series of values, from <parameter>start</parameter> to <parameter>stop</parameter>
       with a step size of <parameter>step</parameter>
      </entry>
     </row>

    </tbody>
   </tgroup>
  </table>

  <para>
   When <parameter>step</parameter> is positive, zero rows are returned if
   <parameter>start</parameter> is greater than <parameter>stop</parameter>.
   Conversely, when <parameter>step</parameter> is negative, zero rows are
   returned if <parameter>start</parameter> is less than <parameter>stop</parameter>.
   Zero rows are also returned for <literal>NULL</literal> inputs. It is an error
   for <parameter>step</parameter> to be zero. Some examples follow:
<programlisting>
select * from generate_series(2,4);
 generate_series
-----------------
               2
               3
               4
(3 rows)

select * from generate_series(5,1,-2);
 generate_series
-----------------
               5
               3
               1
(3 rows)

select * from generate_series(4,3);
 generate_series
-----------------
(0 rows)

select current_date + s.a as dates from generate_series(0,14,7) as s(a);
   dates
------------
 2004-02-05
 2004-02-12
 2004-02-19
(3 rows)
</programlisting>
  </para>
 </sect1>

 <sect1 id="functions-info">
  <title>System Information Functions</title>

  <para>
   <xref linkend="functions-info-session-table"> shows several
   functions that extract session and system information.
  </para>

   <table id="functions-info-session-table">
    <title>Session Information Functions</title>
    <tgroup cols="3">
     <thead>
      <row><entry>Name</entry> <entry>Return Type</entry> <entry>Description</entry></row>
     </thead>

     <tbody>
      <row>
       <entry><function>current_database()</function></entry>
       <entry><type>name</type></entry>
       <entry>name of current database</entry>
      </row>

      <row>
       <entry><function>current_schema()</function></entry>
       <entry><type>name</type></entry>
       <entry>name of current schema</entry>
      </row>

      <row>
       <entry><function>current_schemas(boolean)</function></entry>
       <entry><type>name[]</type></entry>
       <entry>names of schemas in search path optionally including implicit schemas</entry>
      </row>

      <row>
       <entry><function>current_user</function></entry>
       <entry><type>name</type></entry>
       <entry>user name of current execution context</entry>
      </row>

      <row>
       <entry><function>inet_client_addr()</function></entry>
       <entry><type>inet</type></entry>
       <entry>address of the remote connection</entry>
      </row>

      <row>
       <entry><function>inet_client_port()</function></entry>
       <entry><type>int4</type></entry>
       <entry>port of the remote connection</entry>
      </row>

      <row>
       <entry><function>inet_server_addr()</function></entry>
       <entry><type>inet</type></entry>
       <entry>address of the local connection</entry>
      </row>

      <row>
       <entry><function>inet_server_port()</function></entry>
       <entry><type>int4</type></entry>
       <entry>port of the local connection</entry>
      </row>

      <row>
       <entry><function>session_user</function></entry>
       <entry><type>name</type></entry>
       <entry>session user name</entry>
      </row>

      <row>
       <entry><function>user</function></entry>
       <entry><type>name</type></entry>
       <entry>equivalent to <function>current_user</function></entry>
      </row>

      <row>
       <entry><function>version()</function></entry>
       <entry><type>text</type></entry>
       <entry>PostgreSQL version information</entry>
      </row>
     </tbody>
    </tgroup>
   </table>

   <indexterm zone="functions-info">
    <primary>user</primary>
    <secondary>current</secondary>
   </indexterm>

   <indexterm zone="functions-info">
    <primary>schema</primary>
    <secondary>current</secondary>
   </indexterm>

   <indexterm zone="functions-info">
    <primary>search path</primary>
    <secondary>current</secondary>
   </indexterm>

   <para>
    The <function>session_user</function> is normally the user who initiated
    the current database connection; but superusers can change this setting
    with <xref linkend="sql-set-session-authorization" endterm="sql-set-session-authorization-title">.
    The <function>current_user</function> is the user identifier
    that is applicable for permission checking. Normally, it is equal
    to the session user, but it changes during the execution of
    functions with the attribute <literal>SECURITY DEFINER</literal>.
    In Unix parlance, the session user is the <quote>real user</quote> and
    the current user is the <quote>effective user</quote>.
   </para>

   <note>
    <para>
     <function>current_user</function>, <function>session_user</function>, and
     <function>user</function> have special syntactic status in <acronym>SQL</acronym>:
     they must be called without trailing parentheses.
    </para>
   </note>

   <para>
    <function>current_schema</function> returns the name of the schema that is
    at the front of the search path (or a null value if the search path is
    empty).  This is the schema that will be used for any tables or
    other named objects that are created without specifying a target schema.
    <function>current_schemas(boolean)</function> returns an array of the names of all
    schemas presently in the search path.  The Boolean option determines whether or not
    implicitly included system schemas such as <literal>pg_catalog</> are included in the search 
    path returned.
   </para>

   <note>
    <para>
     The search path may be altered at run time.  The command is:
<programlisting>
SET search_path TO <replaceable>schema</> <optional>, <replaceable>schema</>, ...</optional>
</programlisting>
    </para>
   </note>

   <indexterm zone="functions-info">
    <primary>inet_client_addr</primary>
   </indexterm>

   <indexterm zone="functions-info">
    <primary>inet_client_port</primary>
   </indexterm>

   <indexterm zone="functions-info">
    <primary>inet_server_addr</primary>
   </indexterm>

   <indexterm zone="functions-info">
    <primary>inet_server_port</primary>
   </indexterm>

   <para>
     <function>inet_client_addr</function> returns the IP address of the
     current client, and <function>inet_client_port</function> returns the
     port number.
     <function>inet_server_addr</function> returns the IP address on which
     the server accepted the current connection, and
     <function>inet_server_port</function> returns the port number.
     All these functions return NULL if the current connection is via a
     Unix-domain socket.
   </para>

   <indexterm zone="functions-info">
    <primary>version</primary>
   </indexterm>

   <para>
    <function>version()</function> returns a string describing the
    <productname>PostgreSQL</productname> server's version.
   </para>

  <indexterm>
   <primary>privilege</primary>
   <secondary>querying</secondary>
  </indexterm>

  <para>
   <xref linkend="functions-info-access-table"> lists functions that
   allow the user to query object access privileges programmatically.
   See <xref linkend="ddl-priv"> for more information about
   privileges.
  </para>

   <table id="functions-info-access-table">
    <title>Access Privilege Inquiry Functions</title>
    <tgroup cols="3">
     <thead>
      <row><entry>Name</entry> <entry>Return Type</entry> <entry>Description</entry></row>
     </thead>

     <tbody>
      <row>
       <entry><literal><function>has_table_privilege</function>(<parameter>user</parameter>,
                                  <parameter>table</parameter>,
                                  <parameter>privilege</parameter>)</literal>
       </entry>
       <entry><type>boolean</type></entry>
       <entry>does user have privilege for table</entry>
      </row>
      <row>
       <entry><literal><function>has_table_privilege</function>(<parameter>table</parameter>,
                                  <parameter>privilege</parameter>)</literal>
       </entry>
       <entry><type>boolean</type></entry>
       <entry>does current user have privilege for table</entry>
      </row>
      <row>
       <entry><literal><function>has_database_privilege</function>(<parameter>user</parameter>,
                                  <parameter>database</parameter>,
                                  <parameter>privilege</parameter>)</literal>
       </entry>
       <entry><type>boolean</type></entry>
       <entry>does user have privilege for database</entry>
      </row>
      <row>
       <entry><literal><function>has_database_privilege</function>(<parameter>database</parameter>,
                                  <parameter>privilege</parameter>)</literal>
       </entry>
       <entry><type>boolean</type></entry>
       <entry>does current user have privilege for database</entry>
      </row>
      <row>
       <entry><literal><function>has_function_privilege</function>(<parameter>user</parameter>,
                                  <parameter>function</parameter>,
                                  <parameter>privilege</parameter>)</literal>
       </entry>
       <entry><type>boolean</type></entry>
       <entry>does user have privilege for function</entry>
      </row>
      <row>
       <entry><literal><function>has_function_privilege</function>(<parameter>function</parameter>,
                                  <parameter>privilege</parameter>)</literal>
       </entry>
       <entry><type>boolean</type></entry>
       <entry>does current user have privilege for function</entry>
      </row>
      <row>
       <entry><literal><function>has_language_privilege</function>(<parameter>user</parameter>,
                                  <parameter>language</parameter>,
                                  <parameter>privilege</parameter>)</literal>
       </entry>
       <entry><type>boolean</type></entry>
       <entry>does user have privilege for language</entry>
      </row>
      <row>
       <entry><literal><function>has_language_privilege</function>(<parameter>language</parameter>,
                                  <parameter>privilege</parameter>)</literal>
       </entry>
       <entry><type>boolean</type></entry>
       <entry>does current user have privilege for language</entry>
      </row>
      <row>
       <entry><literal><function>has_schema_privilege</function>(<parameter>user</parameter>,
                                  <parameter>schema</parameter>,
                                  <parameter>privilege</parameter>)</literal>
       </entry>
       <entry><type>boolean</type></entry>
       <entry>does user have privilege for schema</entry>
      </row>
      <row>
       <entry><literal><function>has_schema_privilege</function>(<parameter>schema</parameter>,
                                  <parameter>privilege</parameter>)</literal>
       </entry>
       <entry><type>boolean</type></entry>
       <entry>does current user have privilege for schema</entry>
      </row>
      <row>
       <entry><literal><function>has_tablespace_privilege</function>(<parameter>user</parameter>,
                                  <parameter>tablespace</parameter>,
                                  <parameter>privilege</parameter>)</literal>
       </entry>
       <entry><type>boolean</type></entry>
       <entry>does user have privilege for tablespace</entry>
      </row>
      <row>
       <entry><literal><function>has_tablespace_privilege</function>(<parameter>tablespace</parameter>,
                                  <parameter>privilege</parameter>)</literal>
       </entry>
       <entry><type>boolean</type></entry>
       <entry>does current user have privilege for tablespace</entry>
      </row>
     </tbody>
    </tgroup>
   </table>

   <indexterm zone="functions-info">
    <primary>has_table_privilege</primary>
   </indexterm>
   <indexterm zone="functions-info">
    <primary>has_database_privilege</primary>
   </indexterm>
   <indexterm zone="functions-info">
    <primary>has_function_privilege</primary>
   </indexterm>
   <indexterm zone="functions-info">
    <primary>has_language_privilege</primary>
   </indexterm>
   <indexterm zone="functions-info">
    <primary>has_schema_privilege</primary>
   </indexterm>
   <indexterm zone="functions-info">
    <primary>has_tablespace_privilege</primary>
   </indexterm>

   <para>
    <function>has_table_privilege</function> checks whether a user
    can access a table in a particular way.  The user can be
    specified by name or by ID
    (<literal>pg_user.usesysid</literal>), or if the argument is
    omitted
    <function>current_user</function> is assumed.  The table can be specified
    by name or by OID.  (Thus, there are actually six variants of
    <function>has_table_privilege</function>, which can be distinguished by
    the number and types of their arguments.)  When specifying by name,
    the name can be schema-qualified if necessary.
    The desired access privilege type
    is specified by a text string, which must evaluate to one of the
    values <literal>SELECT</literal>, <literal>INSERT</literal>, <literal>UPDATE</literal>,
    <literal>DELETE</literal>, <literal>RULE</literal>, <literal>REFERENCES</literal>, or
    <literal>TRIGGER</literal>.  (Case of the string is not significant, however.)
    An example is:
<programlisting>
SELECT has_table_privilege('myschema.mytable', 'select');
</programlisting>
   </para>

   <para>
    <function>has_database_privilege</function> checks whether a user
    can access a database in a particular way.  The possibilities for its
    arguments are analogous to <function>has_table_privilege</function>.
    The desired access privilege type must evaluate to
    <literal>CREATE</literal>,
    <literal>TEMPORARY</literal>, or
    <literal>TEMP</literal> (which is equivalent to
    <literal>TEMPORARY</literal>).
   </para>

   <para>
    <function>has_function_privilege</function> checks whether a user
    can access a function in a particular way.  The possibilities for its
    arguments are analogous to <function>has_table_privilege</function>.
    When specifying a function by a text string rather than by OID,
    the allowed input is the same as for the <type>regprocedure</> data type
    (see <xref linkend="datatype-oid">).
    The desired access privilege type must evaluate to
    <literal>EXECUTE</literal>.
    An example is:
<programlisting>
SELECT has_function_privilege('joeuser', 'myfunc(int, text)', 'execute');
</programlisting>
   </para>

   <para>
    <function>has_language_privilege</function> checks whether a user
    can access a procedural language in a particular way.  The possibilities
    for its arguments are analogous to <function>has_table_privilege</function>.
    The desired access privilege type must evaluate to
    <literal>USAGE</literal>.
   </para>

   <para>
    <function>has_schema_privilege</function> checks whether a user
    can access a schema in a particular way.  The possibilities for its
    arguments are analogous to <function>has_table_privilege</function>.
    The desired access privilege type must evaluate to
    <literal>CREATE</literal> or
    <literal>USAGE</literal>.
   </para>

   <para>
    <function>has_tablespace_privilege</function> checks whether a user
    can access a tablespace in a particular way.  The possibilities for its
    arguments are analogous to <function>has_table_privilege</function>.
    The desired access privilege type must evaluate to
    <literal>CREATE</literal>.
   </para>

  <para>
   To test whether a user holds a grant option on the privilege,
   append <literal> WITH GRANT OPTION</literal> to the privilege key
   word; for example <literal>'UPDATE WITH GRANT OPTION'</literal>.
  </para>

  <para>
   <xref linkend="functions-info-schema-table"> shows functions that
   determine whether a certain object is <firstterm>visible</> in the
   current schema search path.  A table is said to be visible if its
   containing schema is in the search path and no table of the same
   name appears earlier in the search path.  This is equivalent to the
   statement that the table can be referenced by name without explicit
   schema qualification.  For example, to list the names of all
   visible tables:
<programlisting>
SELECT relname FROM pg_class WHERE pg_table_is_visible(oid);
</programlisting>
  </para>

   <table id="functions-info-schema-table">
    <title>Schema Visibility Inquiry Functions</title>
    <tgroup cols="3">
     <thead>
      <row><entry>Name</entry> <entry>Return Type</entry> <entry>Description</entry></row>
     </thead>

     <tbody>
      <row>
       <entry><literal><function>pg_table_is_visible</function>(<parameter>table_oid</parameter>)</literal>
       </entry>
       <entry><type>boolean</type></entry>
       <entry>is table visible in search path</entry>
      </row>
      <row>
       <entry><literal><function>pg_type_is_visible</function>(<parameter>type_oid</parameter>)</literal>
       </entry>
       <entry><type>boolean</type></entry>
       <entry>is type (or domain) visible in search path</entry>
      </row>
      <row>
       <entry><literal><function>pg_function_is_visible</function>(<parameter>function_oid</parameter>)</literal>
       </entry>
       <entry><type>boolean</type></entry>
       <entry>is function visible in search path</entry>
      </row>
      <row>
       <entry><literal><function>pg_operator_is_visible</function>(<parameter>operator_oid</parameter>)</literal>
       </entry>
       <entry><type>boolean</type></entry>
       <entry>is operator visible in search path</entry>
      </row>
      <row>
       <entry><literal><function>pg_opclass_is_visible</function>(<parameter>opclass_oid</parameter>)</literal>
       </entry>
       <entry><type>boolean</type></entry>
       <entry>is operator class visible in search path</entry>
      </row>
      <row>
       <entry><literal><function>pg_conversion_is_visible</function>(<parameter>conversion_oid</parameter>)</literal>
       </entry>
       <entry><type>boolean</type></entry>
       <entry>is conversion visible in search path</entry>
      </row>
     </tbody>
    </tgroup>
   </table>

   <indexterm zone="functions-info">
    <primary>pg_table_is_visible</primary>
   </indexterm>
   <indexterm zone="functions-info">
    <primary>pg_type_is_visible</primary>
   </indexterm>
   <indexterm zone="functions-info">
    <primary>pg_function_is_visible</primary>
   </indexterm>
   <indexterm zone="functions-info">
    <primary>pg_operator_is_visible</primary>
   </indexterm>
   <indexterm zone="functions-info">
    <primary>pg_opclass_is_visible</primary>
   </indexterm>
   <indexterm zone="functions-info">
    <primary>pg_conversion_is_visible</primary>
   </indexterm>

   <para>
   <function>pg_table_is_visible</function> performs the check for
   tables (or views, or any other kind of <literal>pg_class</> entry).
   <function>pg_type_is_visible</function>,
   <function>pg_function_is_visible</function>,
   <function>pg_operator_is_visible</function>,
   <function>pg_opclass_is_visible</function>, and
   <function>pg_conversion_is_visible</function> perform the same sort of
   visibility check for types (and domains), functions, operators, operator classes
   and conversions, respectively.  For functions and operators, an object in
   the search path is visible if there is no object of the same name
   <emphasis>and argument data type(s)</> earlier in the path.  For
   operator classes, both name and associated index access method are
   considered.
   </para>

   <para>
    All these functions require object OIDs to identify the object to be
    checked.  If you want to test an object by name, it is convenient to use
    the OID alias types (<type>regclass</>, <type>regtype</>,
    <type>regprocedure</>, or <type>regoperator</>), for example
<programlisting>
SELECT pg_type_is_visible('myschema.widget'::regtype);
</programlisting>
    Note that it would not make much sense to test an unqualified name in
    this way &mdash; if the name can be recognized at all, it must be visible.
   </para>

   <indexterm zone="functions-info">
    <primary>format_type</primary>
   </indexterm>

   <indexterm zone="functions-info">
    <primary>pg_get_viewdef</primary>
   </indexterm>

   <indexterm zone="functions-info">
    <primary>pg_get_ruledef</primary>
   </indexterm>

   <indexterm zone="functions-info">
    <primary>pg_get_indexdef</primary>
   </indexterm>

   <indexterm zone="functions-info">
    <primary>pg_get_triggerdef</primary>
   </indexterm>

   <indexterm zone="functions-info">
    <primary>pg_get_constraintdef</primary>
   </indexterm>

   <indexterm zone="functions-info">
    <primary>pg_get_expr</primary>
   </indexterm>

   <indexterm zone="functions-info">
    <primary>pg_get_userbyid</primary>
   </indexterm>

   <indexterm zone="functions-info">
    <primary>pg_get_serial_sequence</primary>
   </indexterm>

   <indexterm zone="functions-info">
    <primary>pg_tablespace_databases</primary>
   </indexterm>

  <para>
   <xref linkend="functions-info-catalog-table"> lists functions that
   extract information from the system catalogs.
  </para>

   <table id="functions-info-catalog-table">
    <title>System Catalog Information Functions</title>
    <tgroup cols="3">
     <thead>
      <row><entry>Name</entry> <entry>Return Type</entry> <entry>Description</entry></row>
     </thead>

     <tbody>
      <row>
       <entry><literal><function>format_type</function>(<parameter>type_oid</parameter>, <parameter>typemod</>)</literal></entry>
       <entry><type>text</type></entry>
       <entry>get SQL name of a data type</entry>
      </row>
      <row>
       <entry><literal><function>pg_get_viewdef</function>(<parameter>view_name</parameter>)</literal></entry>
       <entry><type>text</type></entry>
       <entry>get <command>CREATE VIEW</> command for view (<emphasis>deprecated</emphasis>)</entry>
      </row>
      <row>
       <entry><literal><function>pg_get_viewdef</function>(<parameter>view_name</parameter>, <parameter>pretty_bool</>)</literal></entry>
       <entry><type>text</type></entry>
       <entry>get <command>CREATE VIEW</> command for view (<emphasis>deprecated</emphasis>)</entry>
      </row>
      <row>
       <entry><literal><function>pg_get_viewdef</function>(<parameter>view_oid</parameter>)</literal></entry>
       <entry><type>text</type></entry>
       <entry>get <command>CREATE VIEW</> command for view</entry>
      </row>
      <row>
       <entry><literal><function>pg_get_viewdef</function>(<parameter>view_oid</parameter>, <parameter>pretty_bool</>)</literal></entry>
       <entry><type>text</type></entry>
       <entry>get <command>CREATE VIEW</> command for view</entry>
      </row>
      <row>
       <entry><literal><function>pg_get_ruledef</function>(<parameter>rule_oid</parameter>)</literal></entry>
       <entry><type>text</type></entry>
       <entry>get <command>CREATE RULE</> command for rule</entry>
      </row>
      <row>
       <entry><literal><function>pg_get_ruledef</function>(<parameter>rule_oid</parameter>, <parameter>pretty_bool</>)</literal></entry>
       <entry><type>text</type></entry>
       <entry>get <command>CREATE RULE</> command for rule</entry>
      </row>
      <row>
       <entry><literal><function>pg_get_indexdef</function>(<parameter>index_oid</parameter>)</literal></entry>
       <entry><type>text</type></entry>
       <entry>get <command>CREATE INDEX</> command for index</entry>
      </row>
      <row>
       <entry><literal><function>pg_get_indexdef</function>(<parameter>index_oid</parameter>, <parameter>column_no</>, <parameter>pretty_bool</>)</literal></entry>
       <entry><type>text</type></entry>
       <entry>get <command>CREATE INDEX</> command for index,
       or definition of just one index column when
       <parameter>column_no</> is not zero</entry>
      </row>
      <row>
       <entry><function>pg_get_triggerdef</function>(<parameter>trigger_oid</parameter>)</entry>
       <entry><type>text</type></entry>
       <entry>get <command>CREATE [ CONSTRAINT ] TRIGGER</> command for trigger</entry>
      </row>
      <row>
       <entry><literal><function>pg_get_constraintdef</function>(<parameter>constraint_oid</parameter>)</literal></entry>
       <entry><type>text</type></entry>
       <entry>get definition of a constraint</entry>
      </row>
      <row>
       <entry><literal><function>pg_get_constraintdef</function>(<parameter>constraint_oid</parameter>, <parameter>pretty_bool</>)</literal></entry>
       <entry><type>text</type></entry>
       <entry>get definition of a constraint</entry>
      </row>
      <row>
       <entry><literal><function>pg_get_expr</function>(<parameter>expr_text</parameter>, <parameter>relation_oid</>)</literal></entry>
       <entry><type>text</type></entry>
       <entry>decompile internal form of an expression, assuming that any Vars
       in it refer to the relation indicated by the second parameter</entry>
      </row>
      <row>
       <entry><literal><function>pg_get_expr</function>(<parameter>expr_text</parameter>, <parameter>relation_oid</>, <parameter>pretty_bool</>)</literal></entry>
       <entry><type>text</type></entry>
       <entry>decompile internal form of an expression, assuming that any Vars
       in it refer to the relation indicated by the second parameter</entry>
      </row>
      <row>
       <entry><literal><function>pg_get_userbyid</function>(<parameter>userid</parameter>)</literal></entry>
       <entry><type>name</type></entry>
       <entry>get user name with given ID</entry>
      </row>
      <row>
       <entry><literal><function>pg_get_serial_sequence</function>(<parameter>table_name</parameter>, <parameter>column_name</parameter>)</literal></entry>
       <entry><type>text</type></entry>
       <entry>get name of the sequence that a <type>serial</type> or <type>bigserial</type> column
       uses</entry>
      </row>
      <row>
       <entry><literal><function>pg_tablespace_databases</function>(<parameter>tablespace_oid</parameter>)</literal></entry>
       <entry><type>setof oid</type></entry>
       <entry>get set of database OIDs that have objects in the tablespace</entry>
      </row>
     </tbody>
    </tgroup>
   </table>

  <para>
   <function>format_type</function> returns the SQL name of a data type that
   is identified by its type OID and possibly a type modifier.  Pass NULL
   for the type modifier if no specific modifier is known.
  </para>

  <para>
   <function>pg_get_viewdef</function>,
   <function>pg_get_ruledef</function>,
   <function>pg_get_indexdef</function>,
   <function>pg_get_triggerdef</function>, and
   <function>pg_get_constraintdef</function> respectively
   reconstruct the creating command for a view, rule, index, trigger, or
   constraint.  (Note that this is a decompiled reconstruction, not
   the original text of the command.)
   <function>pg_get_expr</function> decompiles the internal form of an
   individual expression, such as the default value for a column.  It
   may be useful when examining the contents of system catalogs.
   Most of these functions come in two
   variants, one of which can optionally <quote>pretty-print</> the result.
   The pretty-printed format is more readable, but the default format is more
   likely to be
   interpreted the same way by future versions of <productname>PostgreSQL</>;
   avoid using pretty-printed output for dump purposes.
   Passing <literal>false</> for the pretty-print parameter yields the
   same result as the variant that does not have the parameter at all.
  </para>

  <para>
   <function>pg_get_userbyid</function>
   extracts a user's name given a user ID number.
   <function>pg_get_serial_sequence</function>
   fetches the name of the sequence associated with a serial or
   bigserial column.  The name is suitably formatted
   for passing to the sequence functions (see <xref
   linkend="functions-sequence">).
   NULL is returned if the column does not have a sequence attached.
  </para>

  <para>
  <function>pg_tablespace_databases</function> allows usage examination of a
  tablespace. It will return a set of OIDs of databases that have objects
  stored in the tablespace. If this function returns any row, the
  tablespace is not empty and cannot be dropped. To
  display the specific objects populating the tablespace, you will need
  to connect to the databases identified by 
  <function>pg_tablespace_databases</function> and query their
  <structname>pg_class</> catalogs.
  </para>

   <indexterm zone="functions-info">
    <primary>obj_description</primary>
   </indexterm>

   <indexterm zone="functions-info">
    <primary>col_description</primary>
   </indexterm>

   <indexterm zone="functions-info">
    <primary>comment</primary>
    <secondary sortas="database objects">about database objects</secondary>
   </indexterm>

   <para>
    The functions shown in <xref
    linkend="functions-info-comment-table"> extract comments
    previously stored with the <command>COMMENT</command> command.  A
    null value is returned if no comment could be found matching the
    specified parameters.
   </para>

   <table id="functions-info-comment-table">
    <title>Comment Information Functions</title>
    <tgroup cols="3">
     <thead>
      <row><entry>Name</entry> <entry>Return Type</entry> <entry>Description</entry></row>
     </thead>

     <tbody>
      <row>
       <entry><literal><function>obj_description</function>(<parameter>object_oid</parameter>, <parameter>catalog_name</parameter>)</literal></entry>
       <entry><type>text</type></entry>
       <entry>get comment for a database object</entry>
      </row>
      <row>
       <entry><literal><function>obj_description</function>(<parameter>object_oid</parameter>)</literal></entry>
       <entry><type>text</type></entry>
       <entry>get comment for a database object (<emphasis>deprecated</emphasis>)</entry>
      </row>
      <row>
       <entry><literal><function>col_description</function>(<parameter>table_oid</parameter>, <parameter>column_number</parameter>)</literal></entry>
       <entry><type>text</type></entry>
       <entry>get comment for a table column</entry>
      </row>
     </tbody>
    </tgroup>
   </table>

   <para>
    The two-parameter form of <function>obj_description</function> returns the
    comment for a database object specified by its OID and the name of the
    containing system catalog.  For example,
    <literal>obj_description(123456,'pg_class')</literal>
    would retrieve the comment for a table with OID 123456.
    The one-parameter form of <function>obj_description</function> requires only
    the object OID.  It is now deprecated since there is no guarantee that
    OIDs are unique across different system catalogs; therefore, the wrong
    comment could be returned.
   </para>

   <para>
    <function>col_description</function> returns the comment for a table column,
    which is specified by the OID of its table and its column number.
    <function>obj_description</function> cannot be used for table columns since
    columns do not have OIDs of their own.
   </para>
  </sect1>

 <sect1 id="functions-admin">
  <title>System Administration Functions</title>

  <para>
   <xref linkend="functions-admin-set-table"> shows the functions
   available to query and alter run-time configuration parameters.
  </para>

   <table id="functions-admin-set-table">
    <title>Configuration Settings Functions</title>
    <tgroup cols="3">
     <thead>
      <row><entry>Name</entry> <entry>Return Type</entry> <entry>Description</entry></row>
     </thead>

     <tbody>
      <row>
       <entry>
        <literal><function>current_setting</function>(<parameter>setting_name</parameter>)</literal>
       </entry>
       <entry><type>text</type></entry>
       <entry>current value of setting</entry>
      </row>
      <row>
       <entry>
        <literal><function>set_config(<parameter>setting_name</parameter>,
                             <parameter>new_value</parameter>,
                             <parameter>is_local</parameter>)</function></literal>
       </entry>
       <entry><type>text</type></entry>
       <entry>set parameter and return new value</entry>
      </row>
     </tbody>
    </tgroup>
   </table>

   <indexterm zone="functions-admin">
    <primary>SET</primary>
   </indexterm>

   <indexterm zone="functions-admin">
    <primary>SHOW</primary>
   </indexterm>

   <indexterm zone="functions-admin">
    <primary>configuration</primary>
    <secondary sortas="server">of the server</secondary>
    <tertiary>functions</tertiary>
   </indexterm>

   <para>
    The function <function>current_setting</function> yields the
    current value of the setting <parameter>setting_name</parameter>.
    It corresponds to the <acronym>SQL</acronym> command
    <command>SHOW</command>.  An example:
<programlisting>
SELECT current_setting('datestyle');

 current_setting
-----------------
 ISO, MDY
(1 row)
</programlisting>
   </para>

   <para>
    <function>set_config</function> sets the parameter
    <parameter>setting_name</parameter> to
    <parameter>new_value</parameter>.  If
    <parameter>is_local</parameter> is <literal>true</literal>, the
    new value will only apply to the current transaction. If you want
    the new value to apply for the current session, use
    <literal>false</literal> instead. The function corresponds to the
    SQL command <command>SET</command>. An example:
<programlisting>
SELECT set_config('log_statement_stats', 'off', false);

 set_config
------------
 off
(1 row)
</programlisting>
   </para>

   <indexterm zone="functions-admin">
    <primary>pg_cancel_backend</primary>
   </indexterm>

   <indexterm zone="functions-admin">
    <primary>signal</primary>
    <secondary sortas="backend">backend processes</secondary>
   </indexterm>

   <para>
    The function shown in <xref
    linkend="functions-admin-signal-table"> sends control signals to
    other server processes.  Use of this function is restricted
    to superusers.
   </para>

   <table id="functions-admin-signal-table">
    <title>Backend Signalling Functions</title>
    <tgroup cols="3">
     <thead>
      <row><entry>Name</entry> <entry>Return Type</entry> <entry>Description</entry>
      </row>
     </thead>

     <tbody>
      <row>
       <entry>
        <literal><function>pg_cancel_backend</function>(<parameter>pid</parameter>)</literal>
        </entry>
       <entry><type>int</type></entry>
       <entry>Cancel a backend's current query</entry>
      </row>
     </tbody>
    </tgroup>
   </table>

   <para>
    This function returns 1 if successful, 0 if not successful.
    The process ID (<literal>pid</literal>) of an active backend can be found
    from the <structfield>procpid</structfield> column in the
    <structname>pg_stat_activity</structname> view, or by listing the <command>postgres</command>
    processes on the server with <application>ps</>.
   </para>

   <indexterm zone="functions-admin">
    <primary>pg_start_backup</primary>
   </indexterm>

   <indexterm zone="functions-admin">
    <primary>pg_stop_backup</primary>
   </indexterm>

   <indexterm zone="functions-admin">
    <primary>backup</primary>
   </indexterm>

   <para>
    The functions shown in <xref
    linkend="functions-admin-backup-table"> assist in making on-line backups.
    Use of these functions is restricted to superusers.
   </para>

   <table id="functions-admin-backup-table">
    <title>Backup Control Functions</title>
    <tgroup cols="3">
     <thead>
      <row><entry>Name</entry> <entry>Return Type</entry> <entry>Description</entry>
      </row>
     </thead>

     <tbody>
      <row>
       <entry>
        <literal><function>pg_start_backup</function>(<parameter>label_text</parameter>)</literal>
        </entry>
       <entry><type>text</type></entry>
       <entry>Set up for performing on-line backup</entry>
      </row>
      <row>
       <entry>
        <literal><function>pg_stop_backup</function>()</literal>
        </entry>
       <entry><type>text</type></entry>
       <entry>Finish performing on-line backup</entry>
      </row>
     </tbody>
    </tgroup>
   </table>

   <para>
    <function>pg_start_backup</> accepts a single parameter which is an
    arbitrary user-defined label for the backup.  (Typically this would be
    the name under which the backup dump file will be stored.)  The function
    writes a backup label file into the database cluster's data directory,
    and then returns the backup's starting WAL offset as text.  (The user
    need not pay any attention to this result value, but it is provided in
    case it is of use.)
   </para>

   <para>
    <function>pg_stop_backup</> removes the label file created by
    <function>pg_start_backup</>, and instead creates a backup history file in
    the WAL archive area.  The history file includes the label given to
    <function>pg_start_backup</>, the starting and ending WAL offsets for
    the backup, and the starting and ending times of the backup.  The return
    value is the backup's ending WAL offset (which again may be of little
    interest).
   </para>

   <para>
    For details about proper usage of these functions, see
    <xref linkend="backup-online">.
   </para>
  </sect1>
</chapter>

<!-- Keep this comment at the end of the file
Local variables:
mode:sgml
sgml-omittag:nil
sgml-shorttag:t
sgml-minimize-attributes:nil
sgml-always-quote-attributes:t
sgml-indent-step:1
sgml-indent-data:t
sgml-parent-document:nil
sgml-default-dtd-file:"./reference.ced"
sgml-exposed-tags:nil
sgml-local-catalogs:("/usr/lib/sgml/catalog")
sgml-local-ecat-files:nil
End:
-->