]> granicus.if.org Git - postgresql/commitdiff
Add functions pg_start_backup, pg_stop_backup to create backup label
authorTom Lane <tgl@sss.pgh.pa.us>
Tue, 3 Aug 2004 20:32:36 +0000 (20:32 +0000)
committerTom Lane <tgl@sss.pgh.pa.us>
Tue, 3 Aug 2004 20:32:36 +0000 (20:32 +0000)
and history files as per recent discussion.  While at it, remove
pg_terminate_backend, since we have decided we do not have time during
this release cycle to address the reliability concerns it creates.
Split the 'Miscellaneous Functions' documentation section into
'System Information Functions' and 'System Administration Functions',
which hopefully will draw the eyes of those looking for such things.

12 files changed:
doc/src/sgml/backup.sgml
doc/src/sgml/ddl.sgml
doc/src/sgml/func.sgml
doc/src/sgml/ref/set.sgml
doc/src/sgml/ref/show.sgml
src/backend/access/transam/xlog.c
src/backend/postmaster/pgarch.c
src/backend/utils/adt/misc.c
src/include/access/xlog_internal.h
src/include/catalog/catversion.h
src/include/catalog/pg_proc.h
src/include/utils/builtins.h

index b8b958296cc8c5434e947195990f8559838b12ce..8b171f3697e36e1eaab58341f8445f8a9072ae20 100644 (file)
@@ -1,5 +1,5 @@
 <!--
-$PostgreSQL: pgsql/doc/src/sgml/backup.sgml,v 2.39 2004/04/22 07:02:35 neilc Exp $
+$PostgreSQL: pgsql/doc/src/sgml/backup.sgml,v 2.40 2004/08/03 20:32:30 tgl Exp $
 -->
 <chapter id="backup">
  <title>Backup and Restore</title>
@@ -14,12 +14,14 @@ $PostgreSQL: pgsql/doc/src/sgml/backup.sgml,v 2.39 2004/04/22 07:02:35 neilc Exp
  </para>
 
  <para>
-  There are two fundamentally different approaches to backing up
+  There are three fundamentally different approaches to backing up
   <productname>PostgreSQL</> data:
   <itemizedlist>
    <listitem><para><acronym>SQL</> dump</para></listitem>
    <listitem><para>File system level backup</para></listitem>
+   <listitem><para>On-line backup</para></listitem>
   </itemizedlist>
+  Each has its own strengths and weaknesses.
  </para>
 
  <sect1 id="backup-dump">
@@ -314,8 +316,8 @@ tar -cf backup.tar /usr/local/pgsql/data
       The database server <emphasis>must</> be shut down in order to
       get a usable backup. Half-way measures such as disallowing all
       connections will <emphasis>not</emphasis> work
-      (<command>tar</command> and similar tools do not take an atomic
-      snapshot of the state of the filesystem at a point in
+      (mainly because <command>tar</command> and similar tools do not take an
+      atomic snapshot of the state of the filesystem at a point in
       time). Information about stopping the server can be found in
       <xref linkend="postmaster-shutdown">.  Needless to say that you
       also need to shut down the server before restoring the data.
@@ -335,7 +337,8 @@ tar -cf backup.tar /usr/local/pgsql/data
       information. Of course it is also impossible to restore only a
       table and the associated <filename>pg_clog</filename> data
       because that would render all other tables in the database
-      cluster useless.
+      cluster useless.  So file system backups only work for complete
+      restoration of an entire database cluster.
      </para>
     </listitem>
    </orderedlist>
@@ -355,7 +358,7 @@ tar -cf backup.tar /usr/local/pgsql/data
    properly shut down; therefore, when you start the database server
    on the backed-up data, it will think the server had crashed
    and replay the WAL log.  This is not a problem, just be aware of
-   it.
+   it (and be sure to include the WAL files in your dump).
   </para>
 
   <para>
@@ -373,6 +376,70 @@ tar -cf backup.tar /usr/local/pgsql/data
    the contents of indexes for example, just the commands to recreate
    them.)
   </para>
+ </sect1>
+
+ <sect1 id="backup-online">
+  <title>On-line backup and point-in-time recovery</title>
+
+  <para>
+   At all times, <productname>PostgreSQL</> maintains a <firstterm>write ahead
+   log</> (WAL) that shows details of every change made to the database's data
+   files.  This log exists primarily for crash-safety purposes: if the system
+   crashes, the database can be restored to consistency by <quote>replaying</>
+   the log entries made since the last checkpoint.  However, the existence
+   of the log makes it possible to use a third strategy for backing up
+   databases: we can combine a filesystem-level backup with backup of the WAL
+   files.  If recovery is needed, we restore the backup and then replay from
+   the backed-up WAL files to bring the backup up to current time.  This
+   approach is notably more complex to administer than either of the previous
+   approaches, but it has some significant benefits to offer:
+  <itemizedlist>
+   <listitem>
+    <para>
+     We do not need a perfectly consistent backup as the starting point.
+     Any internal inconsistency in the backup will be corrected by log
+     replay (this is not significantly different from what happens during
+     crash recovery).  So we don't need filesystem snapshot capability,
+     just <application>tar</> or a similar archiving tool.
+    </para>
+   </listitem>
+   <listitem>
+    <para>
+     Since we can string together an indefinitely long sequence of WAL files
+     for replay, continuous backup can be had simply by continuing to archive
+     the WAL files.  This is particularly valuable for large databases, where
+     making a full backup may take an unreasonable amount of time.
+    </para>
+   </listitem>
+   <listitem>
+    <para>
+     There is nothing that says we have to replay the WAL entries all the
+     way to the end.  We could stop the replay at any point and have a
+     consistent snapshot of the database as it was at that time.  Thus,
+     this technique supports <firstterm>point-in-time recovery</>: it is
+     possible to restore the database to its state at any time since your base
+     backup was taken.
+    </para>
+   </listitem>
+   <listitem>
+    <para>
+     If we continuously feed the series of WAL files to another machine
+     that's been loaded with the same base backup, we have a <quote>hot
+     standby</> system: at any point we can bring up the second machine
+     and it will have a nearly-current copy of the database.
+    </para>
+   </listitem>
+  </itemizedlist>
+  </para>
+
+  <para>
+   As with the plain filesystem-backup technique, this method can only
+   support restoration of an entire database cluster, not a subset.
+   Also, it requires a lot of archival storage: the base backup is bulky,
+   and a busy system will generate many megabytes of WAL traffic that
+   have to be archived.  Still, it is the preferred backup technique in
+   many situations where high reliability is needed.
+  </para>
 
  </sect1>
 
@@ -393,16 +460,16 @@ tar -cf backup.tar /usr/local/pgsql/data
    change between major releases of <productname>PostgreSQL</> (where
    the number after the first dot changes). This does not apply to
    different minor releases under the same major release (where the
-   number of the second dot changes); these always have compatible
+   number after the second dot changes); these always have compatible
    storage formats. For example, releases 7.0.1, 7.1.2, and 7.2 are
    not compatible, whereas 7.1.1 and 7.1.2 are. When you update
-   between compatible versions, then you can simply reuse the data
-   area in disk by the new executables. Otherwise you need to
+   between compatible versions, you can simply replace the executables
+   and reuse the data area on disk. Otherwise you need to
    <quote>back up</> your data and <quote>restore</> it on the new
    server, using <application>pg_dump</>. (There are checks in place
    that prevent you from doing the wrong thing, so no harm can be done
    by confusing these things.) The precise installation procedure is
-   not subject of this section; these details are in <xref
+   not the subject of this section; those details are in <xref
    linkend="installation">.
   </para>
 
@@ -427,7 +494,7 @@ pg_dumpall -p 5432 | psql -d template1 -p 6543
 
   <para>
    If you cannot or do not want to run two servers in parallel you can
-   do the back up step before installing the new version, bring down
+   do the backup step before installing the new version, bring down
    the server, move the old version out of the way, install the new
    version, start the new server, restore the data. For example:
 
@@ -447,6 +514,14 @@ psql template1 < backup
    you of strategic places to perform these steps.
   </para>
 
+  <para>
+   You will always need a SQL dump (<application>pg_dump</> dump) for
+   migrating to a new release.  Filesystem-level backups (including
+   on-line backups) will not work, for the same reason that you can't
+   just do the update in-place: the file formats won't necessarily be
+   compatible across major releases.
+  </para>
+
   <note>
    <para>
     When you <quote>move the old installation out of the way</quote>
index 8f807fe481a9c5041709aff9785281113ef6f166..404181482bf355c74b0ae66491e772b94d093bb4 100644 (file)
@@ -1,4 +1,4 @@
-<!-- $PostgreSQL: pgsql/doc/src/sgml/ddl.sgml,v 1.26 2004/03/07 04:31:01 neilc Exp $ -->
+<!-- $PostgreSQL: pgsql/doc/src/sgml/ddl.sgml,v 1.27 2004/08/03 20:32:30 tgl Exp $ -->
 
 <chapter id="ddl">
  <title>Data Definition</title>
@@ -1723,7 +1723,7 @@ SET search_path TO myschema;
    </para>
 
    <para>
-    See also <xref linkend="functions-misc"> for other ways to access
+    See also <xref linkend="functions-info"> for other ways to access
     the schema search path.
    </para>
 
index 998f693c79b7eabe279deabd02aad5e3ae661a97..f87b7657b59818843c5469946498d5cdd49bd05e 100644 (file)
@@ -1,5 +1,5 @@
 <!--
-$PostgreSQL: pgsql/doc/src/sgml/func.sgml,v 1.214 2004/07/12 20:23:47 momjian Exp $
+$PostgreSQL: pgsql/doc/src/sgml/func.sgml,v 1.215 2004/08/03 20:32:31 tgl Exp $
 PostgreSQL documentation
 -->
 
@@ -6629,1356 +6629,1185 @@ SELECT NULLIF(value, '(none)') ...
  </sect1>
 
 
- <sect1 id="functions-misc">
-  <title>Miscellaneous Functions</title>
+ <sect1 id="functions-array">
+  <title>Array Functions and Operators</title>
 
   <para>
-   <xref linkend="functions-misc-session-table"> shows several
-   functions that extract session and system information.
+   <xref linkend="array-operators-table"> shows the operators
+   available for <type>array</type> types.
   </para>
 
-   <table id="functions-misc-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-misc">
-    <primary>user</primary>
-    <secondary>current</secondary>
-   </indexterm>
-
-   <indexterm zone="functions-misc">
-    <primary>schema</primary>
-    <secondary>current</secondary>
-   </indexterm>
-
-   <indexterm zone="functions-misc">
-    <primary>search path</primary>
-    <secondary>current</secondary>
-   </indexterm>
-
-   <para>
-    The <function>session_user</function> is the user that initiated a
-    database connection; it is fixed for the duration of that
-    connection. 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>
+    <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>
 
-   <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>
+       <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>
 
-   <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>
+       <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>
 
-   <indexterm zone="functions-misc">
-    <primary>inet_client_addr</primary>
-   </indexterm>
+       <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>
 
-   <indexterm zone="functions-misc">
-    <primary>inet_client_port</primary>
-   </indexterm>
+       <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>
 
-   <indexterm zone="functions-misc">
-    <primary>inet_server_addr</primary>
-   </indexterm>
+       <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>
 
-   <indexterm zone="functions-misc">
-    <primary>inet_server_port</primary>
-   </indexterm>
+       <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>
 
-   <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 connection is via a Unix-domain
-     socket.
-   </para>
+       <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>
 
-   <indexterm zone="functions-misc">
-    <primary>version</primary>
-   </indexterm>
+       <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>
 
-   <para>
-    <function>version()</function> returns a string describing the
-    <productname>PostgreSQL</productname> server's version.
-   </para>
+       <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>
-   <xref linkend="functions-misc-set-table"> shows the functions
-   available to query and alter run-time configuration parameters.
+   See <xref linkend="arrays"> for more details about array operator
+   behavior.
   </para>
 
-   <table id="functions-misc-set-table">
-    <title>Configuration Settings Functions</title>
-    <tgroup cols="3">
-     <thead>
-      <row><entry>Name</entry> <entry>Return Type</entry> <entry>Description</entry></row>
-     </thead>
+  <para>
+   <xref linkend="array-functions-table"> shows the functions
+   available for use with array types. See <xref linkend="arrays">
+   for more discussion and examples for the use of these functions.
+  </para>
 
-     <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>
+    <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, returning <literal>NULL</literal>
+     for <literal>NULL</literal> inputs
+    </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, returning
+     <literal>NULL</literal> for <literal>NULL</literal> inputs
+    </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, returning
+     <literal>NULL</literal> for <literal>NULL</literal> inputs
+    </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 dimension lower and upper bounds,
+     generating an ERROR for <literal>NULL</literal> inputs
+    </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, returning
+     <literal>NULL</literal> for <literal>NULL</literal> inputs
+    </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, returning
+     <literal>NULL</literal> for <literal>NULL</literal> inputs
+    </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, returning
+     <literal>NULL</literal> for <literal>NULL</literal> inputs
+    </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, returning
+     <literal>NULL</literal> for <literal>NULL</literal> inputs
+    </entry>
+       <entry><literal>string_to_array( 'xx~^~yy~^~zz', '~^~')</literal></entry>
+       <entry><literal>{xx,yy,zz}</literal></entry>
+       </row>
+      </tbody>
+     </tgroup>
+    </table>
+  </sect1>
 
-   <indexterm zone="functions-misc">
-    <primary>SET</primary>
-   </indexterm>
+ <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>
 
-   <indexterm zone="functions-misc">
-    <primary>SHOW</primary>
-   </indexterm>
+     <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>
 
-   <indexterm zone="functions-misc">
-    <primary>configuration</primary>
-    <secondary sortas="server">of the server</secondary>
-    <tertiary>functions</tertiary>
-   </indexterm>
+     <row>
+      <entry><function>max(<replaceable class="parameter">expression</replaceable>)</function></entry>
+      <entry>any 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>
 
-   <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');
+     <row>
+      <entry><function>min(<replaceable class="parameter">expression</replaceable>)</function></entry>
+      <entry>any 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>
 
- current_setting
------------------
- ISO, MDY
-(1 row)
-</programlisting>
-   </para>
+     <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>
 
-   <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);
+     <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>
 
- set_config
-------------
- off
-(1 row)
-</programlisting>
-   </para>
+     <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>
 
-  <indexterm>
-   <primary>privilege</primary>
-   <secondary>querying</secondary>
-  </indexterm>
+    </tbody>
+   </tgroup>
+  </table>
 
   <para>
-   <xref linkend="functions-misc-access-table"> lists functions that
-   allow the user to query object access privileges programmatically.
-   See <xref linkend="ddl-priv"> for more information about
-   privileges.
+   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 <function>coalesce</function> may be
+   used to substitute zero for null when necessary.
   </para>
 
-   <table id="functions-misc-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-misc">
-    <primary>has_table_privilege</primary>
-   </indexterm>
-   <indexterm zone="functions-misc">
-    <primary>has_database_privilege</primary>
-   </indexterm>
-   <indexterm zone="functions-misc">
-    <primary>has_function_privilege</primary>
-   </indexterm>
-   <indexterm zone="functions-misc">
-    <primary>has_language_privilege</primary>
-   </indexterm>
-   <indexterm zone="functions-misc">
-    <primary>has_schema_privilege</primary>
-   </indexterm>
-   <indexterm zone="functions-misc">
-    <primary>has_tablespace_privilege</primary>
-   </indexterm>
+  <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>
-    <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:
+    Users accustomed to working with other SQL database management
+    systems may be surprised by the performance characteristics of
+    certain aggregate functions in
+    <productname>PostgreSQL</productname> when the aggregate is
+    applied to the entire table (in other words, no
+    <literal>WHERE</literal> clause is specified). In particular, a
+    query like
 <programlisting>
-SELECT has_table_privilege('myschema.mytable', 'select');
+SELECT min(col) FROM sometable;
 </programlisting>
+    will be executed by <productname>PostgreSQL</productname> using a
+    sequential scan of the entire table. Other database systems may
+    optimize queries of this form to use an index on the column, if
+    one is available. Similarly, the aggregate functions
+    <function>max()</function> and <function>count()</function> always
+    require a sequential scan if applied to the entire table in
+    <productname>PostgreSQL</productname>.
    </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>).
+    <productname>PostgreSQL</productname> cannot easily implement this
+    optimization because it also allows for user-defined aggregate
+    queries. Since <function>min()</function>,
+    <function>max()</function>, and <function>count()</function> are
+    defined using a generic API for aggregate functions, there is no
+    provision for special-casing the execution of these functions
+    under certain circumstances.
    </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.
-    The desired access privilege type must evaluate to
-    <literal>EXECUTE</literal>.
-    An example is:
+    Fortunately, there is a simple workaround for
+    <function>min()</function> and <function>max()</function>. The
+    query shown below is equivalent to the query above, except that it
+    can take advantage of a B-tree index if there is one present on
+    the column in question.
 <programlisting>
-SELECT has_function_privilege('joeuser', 'myfunc(int, text)', 'execute');
+SELECT col FROM sometable ORDER BY col ASC LIMIT 1;
 </programlisting>
+    A similar query (obtained by substituting <literal>DESC</literal>
+    for <literal>ASC</literal> in the query above) can be used in the
+    place of <function>max()</function>).
    </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>.
+    Unfortunately, there is no similarly trivial query that can be
+    used to improve the performance of <function>count()</function>
+    when applied to the entire table.
    </para>
+  </note>
 
-   <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>
+ </sect1>
 
-   <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 evaluate 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>
+ <sect1 id="functions-subquery">
+  <title>Subquery Expressions</title>
 
-  <para>
-   <xref linkend="functions-misc-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>
+  <indexterm>
+   <primary>EXISTS</primary>
+  </indexterm>
 
-   <table id="functions-misc-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>
+  <indexterm>
+   <primary>IN</primary>
+  </indexterm>
 
-     <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>
+   <primary>NOT IN</primary>
+  </indexterm>
 
-   <indexterm zone="functions-misc">
-    <primary>pg_table_is_visible</primary>
-   </indexterm>
-   <indexterm zone="functions-misc">
-    <primary>pg_type_is_visible</primary>
-   </indexterm>
-   <indexterm zone="functions-misc">
-    <primary>pg_function_is_visible</primary>
-   </indexterm>
-   <indexterm zone="functions-misc">
-    <primary>pg_operator_is_visible</primary>
-   </indexterm>
-   <indexterm zone="functions-misc">
-    <primary>pg_opclass_is_visible</primary>
-   </indexterm>
-   <indexterm zone="functions-misc">
-    <primary>pg_conversion_is_visible</primary>
-   </indexterm>
+  <indexterm>
+   <primary>ANY</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>
+  <indexterm>
+   <primary>ALL</primary>
+  </indexterm>
 
-   <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 --- if the name can be recognized at all, it must be visible.
-   </para>
+  <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>
 
-   <indexterm zone="functions-misc">
-    <primary>pg_get_viewdef</primary>
-   </indexterm>
+  <para>
+   The subquery can refer to variables from the surrounding query,
+   which will act as constants during any one evaluation of the subquery.
+  </para>
 
-   <indexterm zone="functions-misc">
-    <primary>pg_get_ruledef</primary>
-   </indexterm>
+  <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>
 
-   <indexterm zone="functions-misc">
-    <primary>pg_get_indexdef</primary>
-   </indexterm>
+  <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>
 
-   <indexterm zone="functions-misc">
-    <primary>pg_get_triggerdef</primary>
-   </indexterm>
+  <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>
 
-   <indexterm zone="functions-misc">
-    <primary>pg_get_constraintdef</primary>
-   </indexterm>
+  <sect2>
+   <title><literal>IN</literal></title>
 
-   <indexterm zone="functions-misc">
-    <primary>pg_get_expr</primary>
-   </indexterm>
+<synopsis>
+<replaceable>expression</replaceable> IN (<replaceable>subquery</replaceable>)
+</synopsis>
 
-   <indexterm zone="functions-misc">
-    <primary>pg_get_userbyid</primary>
-   </indexterm>
+  <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>
 
-   <indexterm zone="functions-misc">
-    <primary>pg_get_serial_sequence</primary>
-   </indexterm>
+  <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>
 
-   <indexterm zone="functions-misc">
-    <primary>pg_tablespace_databases</primary>
-   </indexterm>
+  <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>
-   <xref linkend="functions-misc-catalog-table"> lists functions that
-   extract information from the system catalogs.
+   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>
 
-   <table id="functions-misc-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>
+  <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>
 
-     <tbody>
-      <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 serial or bigserial 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>
+  <sect2>
+   <title><literal>NOT IN </literal></title>
+
+<synopsis>
+<replaceable>expression</replaceable> NOT IN (<replaceable>subquery</replaceable>)
+</synopsis>
 
   <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.
+   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>
-   <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.
+   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>
-  <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.
+   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>
 
-   <indexterm zone="functions-misc">
-    <primary>obj_description</primary>
-   </indexterm>
+  <sect2>
+   <title><literal>ANY</literal>/<literal>SOME</literal></title>
 
-   <indexterm zone="functions-misc">
-    <primary>col_description</primary>
-   </indexterm>
+<synopsis>
+<replaceable>expression</replaceable> <replaceable>operator</replaceable> ANY (<replaceable>subquery</replaceable>)
+<replaceable>expression</replaceable> <replaceable>operator</replaceable> SOME (<replaceable>subquery</replaceable>)
+</synopsis>
 
-   <indexterm zone="functions-misc">
-    <primary>comment</primary>
-    <secondary sortas="database objects">about database objects</secondary>
-   </indexterm>
+  <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>
-    The functions shown in <xref
-    linkend="functions-misc-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>
+  <para>
+   <token>SOME</token> is a synonym for <token>ANY</token>.
+   <token>IN</token> is equivalent to <literal>= ANY</literal>.
+  </para>
 
-   <table id="functions-misc-comment-table">
-    <title>Comment Information Functions</title>
-    <tgroup cols="3">
-     <thead>
-      <row><entry>Name</entry> <entry>Return Type</entry> <entry>Description</entry></row>
-     </thead>
+  <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>
 
-     <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>
+   As with <token>EXISTS</token>, it's unwise to assume that the subquery will
+   be evaluated completely.
+  </para>
 
-   <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>
+<synopsis>
+<replaceable>row_constructor</replaceable> <replaceable>operator</> ANY (<replaceable>subquery</replaceable>)
+<replaceable>row_constructor</replaceable> <replaceable>operator</> SOME (<replaceable>subquery</replaceable>)
+</synopsis>
 
-   <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>
+  <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>
 
-   <indexterm zone="functions-misc">
-    <primary>pg_cancel_backend</primary>
-   </indexterm>
+  <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>
 
-   <indexterm zone="functions-misc">
-    <primary>pg_terminate_backend</primary>
-   </indexterm>
+  <sect2>
+   <title><literal>ALL</literal></title>
 
-   <indexterm zone="functions-misc">
-    <primary>signal</primary>
-    <secondary sortas="backend">backend processes</secondary>
-   </indexterm>
+<synopsis>
+<replaceable>expression</replaceable> <replaceable>operator</replaceable> ALL (<replaceable>subquery</replaceable>)
+</synopsis>
 
-   <para>
-    The functions shown in <xref
-    linkend="functions-misc-signal-table"> send control signals to
-    other server processes.  Use of these functions is restricted
-    to superusers.
-   </para>
+  <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>
 
-   <table id="functions-misc-signal-table">
-    <title>Backend Signalling Functions</title>
-    <tgroup cols="3">
-     <thead>
-      <row><entry>Name</entry> <entry>Return Type</entry> <entry>Description</entry>
-      </row>
-     </thead>
+  <para>
+   <token>NOT IN</token> is equivalent to <literal>&lt;&gt; ALL</literal>.
+  </para>
 
-     <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>
-      <row>
-       <entry>
-       <literal><function>pg_terminate_backend</function>(<parameter>pid</parameter>)</literal>
-       </entry>
-       <entry><type>int</type></entry>
-       <entry>Terminate a backend process</entry>
-      </row>
-     </tbody>
-    </tgroup>
-   </table>
+  <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>
-    These functions return 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 postgres
-    processes on the server.
-   </para>
-  </sect1>
+  <para>
+   As with <token>EXISTS</token>, it's unwise to assume that the subquery will
+   be evaluated completely.
+  </para>
 
- <sect1 id="functions-array">
-  <title>Array Functions and Operators</title>
+<synopsis>
+<replaceable>row_constructor</replaceable> <replaceable>operator</replaceable> ALL (<replaceable>subquery</replaceable>)
+</synopsis>
 
   <para>
-   <xref linkend="array-operators-table"> shows the operators
-   available for <type>array</type> types.
+   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>
 
-    <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>
+  <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>
+    <primary>comparison</primary>
+    <secondary>of rows</secondary>
+   </indexterm>
+
+<synopsis>
+<replaceable>row_constructor</replaceable> <replaceable>operator</replaceable> (<replaceable>subquery</replaceable>)
+</synopsis>
 
-       <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>
+  <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>
 
-       <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>
+  <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>
 
-       <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>
+ <sect1 id="functions-comparisons">
+  <title>Row and Array Comparisons</title>
 
-       <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>
+  <indexterm>
+   <primary>IN</primary>
+  </indexterm>
 
-       <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>
+  <indexterm>
+   <primary>NOT IN</primary>
+  </indexterm>
 
-       <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>
+  <indexterm>
+   <primary>ANY</primary>
+  </indexterm>
 
-       <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>
+  <indexterm>
+   <primary>ALL</primary>
+  </indexterm>
 
-       <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>
+  <indexterm>
+   <primary>SOME</primary>
+  </indexterm>
 
   <para>
-   See <xref linkend="arrays"> for more details about array operator
-   behavior.
+   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>
 
-  <para>
-   <xref linkend="array-functions-table"> shows the functions
-   available for use with array types. See <xref linkend="arrays">
-   for more discussion and examples for the use of these functions.
-  </para>
+  <sect2>
+   <title><literal>IN</literal></title>
 
-    <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, returning <literal>NULL</literal>
-     for <literal>NULL</literal> inputs
-    </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, returning
-     <literal>NULL</literal> for <literal>NULL</literal> inputs
-    </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, returning
-     <literal>NULL</literal> for <literal>NULL</literal> inputs
-    </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 dimension lower and upper bounds,
-     generating an ERROR for <literal>NULL</literal> inputs
-    </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, returning
-     <literal>NULL</literal> for <literal>NULL</literal> inputs
-    </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, returning
-     <literal>NULL</literal> for <literal>NULL</literal> inputs
-    </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, returning
-     <literal>NULL</literal> for <literal>NULL</literal> inputs
-    </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, returning
-     <literal>NULL</literal> for <literal>NULL</literal> inputs
-    </entry>
-       <entry><literal>string_to_array( 'xx~^~yy~^~zz', '~^~')</literal></entry>
-       <entry><literal>{xx,yy,zz}</literal></entry>
-       </row>
-      </tbody>
-     </tgroup>
-    </table>
-  </sect1>
+<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
 
- <sect1 id="functions-aggregate">
-  <title>Aggregate Functions</title>
+<synopsis>
+<replaceable>expression</replaceable> = <replaceable>value1</replaceable>
+OR
+<replaceable>expression</replaceable> = <replaceable>value2</replaceable>
+OR
+...
+</synopsis>
+  </para>
 
-  <indexterm zone="functions-aggregate">
-   <primary>aggregate function</primary>
-   <secondary>built-in</secondary>
-  </indexterm>
+  <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>
-   <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.
+   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>
 
-  <table id="functions-aggregate-table">
-   <title>Aggregate Functions</title>
+  <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>
 
-   <tgroup cols="4">
-    <thead>
-     <row>
-      <entry>Function</entry>
-      <entry>Argument Type</entry>
-      <entry>Return Type</entry>
-      <entry>Description</entry>
-     </row>
-    </thead>
+  <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>
 
-    <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>
+  <sect2>
+   <title><literal>ANY</literal>/<literal>SOME</literal> (array)</title>
 
-     <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>
+<synopsis>
+<replaceable>expression</replaceable> <replaceable>operator</replaceable> ANY (<replaceable>array expression</replaceable>)
+<replaceable>expression</replaceable> <replaceable>operator</replaceable> SOME (<replaceable>array expression</replaceable>)
+</synopsis>
 
-     <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>
+  <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>
 
-     <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>
+  <para>
+   <token>SOME</token> is a synonym for <token>ANY</token>.
+  </para>
+  </sect2>
 
-     <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>
+  <sect2>
+   <title><literal>ALL</literal> (array)</title>
 
-     <row>
-      <entry><function>count(*)</function></entry>
-      <entry></entry>
-      <entry><type>bigint</type></entry>
-      <entry>number of input values</entry>
-     </row>
+<synopsis>
+<replaceable>expression</replaceable> <replaceable>operator</replaceable> ALL (<replaceable>array expression</replaceable>)
+</synopsis>
 
-     <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>
+  <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>
 
-     <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>
+  <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>
 
-     <row>
-      <entry><function>max(<replaceable class="parameter">expression</replaceable>)</function></entry>
-      <entry>any 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>
+  </sect2>
+ </sect1>
 
-     <row>
-      <entry><function>min(<replaceable class="parameter">expression</replaceable>)</function></entry>
-      <entry>any 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>
+ <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>
-       <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>
+      <entry>Function</entry>
+      <entry>Argument Type</entry>
+      <entry>Return Type</entry>
+      <entry>Description</entry>
      </row>
+    </thead>
 
+    <tbody>
      <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><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>
-       <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
+       Generate a series of values, from <parameter>start</parameter> to <parameter>stop</parameter>
+       with a step size of one.
       </entry>
-      <entry>sum of <replaceable class="parameter">expression</replaceable> across all input values</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>
-       <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>
+       Generate a series of values, from <parameter>start</parameter> to <parameter>stop</parameter>
+       with a step size of <parameter>step</parameter>.
       </entry>
-      <entry>sample variance of the input values (square of the sample standard deviation)</entry>
      </row>
 
     </tbody>
@@ -7986,754 +7815,988 @@ SELECT pg_type_is_visible('myschema.widget'::regtype);
   </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 <function>coalesce</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:
+   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 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>
+select * from generate_series(2,4);
+ generate_series
+-----------------
+               2
+               3
+               4
+(3 rows)
 
-  <note>
-   <para>
-    Users accustomed to working with other SQL database management
-    systems may be surprised by the performance characteristics of
-    certain aggregate functions in
-    <productname>PostgreSQL</productname> when the aggregate is
-    applied to the entire table (in other words, no
-    <literal>WHERE</literal> clause is specified). In particular, a
-    query like
-<programlisting>
-SELECT min(col) FROM sometable;
-</programlisting>
-    will be executed by <productname>PostgreSQL</productname> using a
-    sequential scan of the entire table. Other database systems may
-    optimize queries of this form to use an index on the column, if
-    one is available. Similarly, the aggregate functions
-    <function>max()</function> and <function>count()</function> always
-    require a sequential scan if applied to the entire table in
-    <productname>PostgreSQL</productname>.
-   </para>
+select * from generate_series(5,1,-2);
+ generate_series
+-----------------
+               5
+               3
+               1
+(3 rows)
 
-   <para>
-    <productname>PostgreSQL</productname> cannot easily implement this
-    optimization because it also allows for user-defined aggregate
-    queries. Since <function>min()</function>,
-    <function>max()</function>, and <function>count()</function> are
-    defined using a generic API for aggregate functions, there is no
-    provision for special-casing the execution of these functions
-    under certain circumstances.
-   </para>
+select * from generate_series(4,3);
+ generate_series
+-----------------
+(0 rows)
 
-   <para>
-    Fortunately, there is a simple workaround for
-    <function>min()</function> and <function>max()</function>. The
-    query shown below is equivalent to the query above, except that it
-    can take advantage of a B-tree index if there is one present on
-    the column in question.
-<programlisting>
-SELECT col FROM sometable ORDER BY col ASC LIMIT 1;
+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>
-    A similar query (obtained by substituting <literal>DESC</literal>
-    for <literal>ASC</literal> in the query above) can be used in the
-    place of <function>max()</function>).
-   </para>
-
-   <para>
-    Unfortunately, there is no similarly trivial query that can be
-    used to improve the performance of <function>count()</function>
-    when applied to the entire table.
-   </para>
-  </note>
-
+  </para>
  </sect1>
 
+ <sect1 id="functions-info">
+  <title>System Information Functions</title>
 
- <sect1 id="functions-subquery">
-  <title>Subquery Expressions</title>
-
-  <indexterm>
-   <primary>EXISTS</primary>
-  </indexterm>
-
-  <indexterm>
-   <primary>IN</primary>
-  </indexterm>
-
-  <indexterm>
-   <primary>NOT IN</primary>
-  </indexterm>
+  <para>
+   <xref linkend="functions-info-session-table"> shows several
+   functions that extract session and system information.
+  </para>
 
-  <indexterm>
-   <primary>ANY</primary>
-  </indexterm>
+   <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>
 
-  <indexterm>
-   <primary>ALL</primary>
-  </indexterm>
+     <tbody>
+      <row>
+       <entry><function>current_database()</function></entry>
+       <entry><type>name</type></entry>
+       <entry>name of current database</entry>
+      </row>
 
-  <indexterm>
-   <primary>SOME</primary>
-  </indexterm>
+      <row>
+       <entry><function>current_schema()</function></entry>
+       <entry><type>name</type></entry>
+       <entry>name of current schema</entry>
+      </row>
 
-  <indexterm>
-   <primary>subquery</primary>
-  </indexterm>
+      <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>
 
-  <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>
+      <row>
+       <entry><function>current_user</function></entry>
+       <entry><type>name</type></entry>
+       <entry>user name of current execution context</entry>
+      </row>
 
-  <sect2>
-   <title><literal>EXISTS</literal></title>
+      <row>
+       <entry><function>inet_client_addr()</function></entry>
+       <entry><type>inet</type></entry>
+       <entry>address of the remote connection</entry>
+      </row>
 
-<synopsis>
-EXISTS ( <replaceable>subquery</replaceable> )
-</synopsis>
+      <row>
+       <entry><function>inet_client_port()</function></entry>
+       <entry><type>int4</type></entry>
+       <entry>port of the remote connection</entry>
+      </row>
 
-  <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>
+      <row>
+       <entry><function>inet_server_addr()</function></entry>
+       <entry><type>inet</type></entry>
+       <entry>address of the local connection</entry>
+      </row>
 
-  <para>
-   The subquery can refer to variables from the surrounding query,
-   which will act as constants during any one evaluation of the subquery.
-  </para>
+      <row>
+       <entry><function>inet_server_port()</function></entry>
+       <entry><type>int4</type></entry>
+       <entry>port of the local connection</entry>
+      </row>
 
-  <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>
+      <row>
+       <entry><function>session_user</function></entry>
+       <entry><type>name</type></entry>
+       <entry>session user name</entry>
+      </row>
 
-  <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>
+      <row>
+       <entry><function>user</function></entry>
+       <entry><type>name</type></entry>
+       <entry>equivalent to <function>current_user</function></entry>
+      </row>
 
-  <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>
+      <row>
+       <entry><function>version()</function></entry>
+       <entry><type>text</type></entry>
+       <entry>PostgreSQL version information</entry>
+      </row>
+     </tbody>
+    </tgroup>
+   </table>
 
-  <sect2>
-   <title><literal>IN</literal></title>
+   <indexterm zone="functions-info">
+    <primary>user</primary>
+    <secondary>current</secondary>
+   </indexterm>
 
-<synopsis>
-<replaceable>expression</replaceable> IN (<replaceable>subquery</replaceable>)
-</synopsis>
+   <indexterm zone="functions-info">
+    <primary>schema</primary>
+    <secondary>current</secondary>
+   </indexterm>
 
-  <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>
+   <indexterm zone="functions-info">
+    <primary>search path</primary>
+    <secondary>current</secondary>
+   </indexterm>
 
-  <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>
+    The <function>session_user</function> is the user that initiated a
+    database connection; it is fixed for the duration of that
+    connection. 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>
 
-  <para>
-   As with <token>EXISTS</token>, it's unwise to assume that the subquery will
-   be evaluated completely.
-  </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>
 
-<synopsis>
-<replaceable>row_constructor</replaceable> IN (<replaceable>subquery</replaceable>)
-</synopsis>
+   <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>
 
-  <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>
+   <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>
 
-  <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>
+   <indexterm zone="functions-info">
+    <primary>inet_client_addr</primary>
+   </indexterm>
 
-  <sect2>
-   <title><literal>NOT IN </literal></title>
+   <indexterm zone="functions-info">
+    <primary>inet_client_port</primary>
+   </indexterm>
 
-<synopsis>
-<replaceable>expression</replaceable> NOT IN (<replaceable>subquery</replaceable>)
-</synopsis>
+   <indexterm zone="functions-info">
+    <primary>inet_server_addr</primary>
+   </indexterm>
 
-  <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>
+   <indexterm zone="functions-info">
+    <primary>inet_server_port</primary>
+   </indexterm>
 
-  <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>
+     <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 connection is via a Unix-domain
+     socket.
+   </para>
 
-  <para>
-   As with <token>EXISTS</token>, it's unwise to assume that the subquery will
-   be evaluated completely.
-  </para>
+   <indexterm zone="functions-info">
+    <primary>version</primary>
+   </indexterm>
 
-<synopsis>
-<replaceable>row_constructor</replaceable> NOT IN (<replaceable>subquery</replaceable>)
-</synopsis>
+   <para>
+    <function>version()</function> returns a string describing the
+    <productname>PostgreSQL</productname> server's version.
+   </para>
 
-  <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>
+  <indexterm>
+   <primary>privilege</primary>
+   <secondary>querying</secondary>
+  </indexterm>
 
   <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.
+   <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>
-  </sect2>
 
-  <sect2>
-   <title><literal>ANY</literal>/<literal>SOME</literal></title>
+   <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>
 
-<synopsis>
-<replaceable>expression</replaceable> <replaceable>operator</replaceable> ANY (<replaceable>subquery</replaceable>)
-<replaceable>expression</replaceable> <replaceable>operator</replaceable> SOME (<replaceable>subquery</replaceable>)
-</synopsis>
+     <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>
 
-  <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>
+   <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>
-   <token>SOME</token> is a synonym for <token>ANY</token>.
-   <token>IN</token> is equivalent to <literal>= ANY</literal>.
-  </para>
+   <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>
-   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>
+    <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>
-   As with <token>EXISTS</token>, it's unwise to assume that the subquery will
-   be evaluated completely.
-  </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.
+    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>
 
-<synopsis>
-<replaceable>row_constructor</replaceable> <replaceable>operator</> ANY (<replaceable>subquery</replaceable>)
-<replaceable>row_constructor</replaceable> <replaceable>operator</> SOME (<replaceable>subquery</replaceable>)
-</synopsis>
+   <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>
-   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).
+   To evaluate 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>
-   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. 
+   <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>
-  </sect2>
 
-  <sect2>
-   <title><literal>ALL</literal></title>
+   <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>
 
-<synopsis>
-<replaceable>expression</replaceable> <replaceable>operator</replaceable> ALL (<replaceable>subquery</replaceable>)
-</synopsis>
+     <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>
 
-  <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>
+   <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>
-   <token>NOT IN</token> is equivalent to <literal>&lt;&gt; ALL</literal>.
-  </para>
+   <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>
-   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>
+    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 --- if the name can be recognized at all, it must be visible.
+   </para>
 
-  <para>
-   As with <token>EXISTS</token>, it's unwise to assume that the subquery will
-   be evaluated completely.
-  </para>
+   <indexterm zone="functions-info">
+    <primary>pg_get_viewdef</primary>
+   </indexterm>
 
-<synopsis>
-<replaceable>row_constructor</replaceable> <replaceable>operator</replaceable> ALL (<replaceable>subquery</replaceable>)
-</synopsis>
+   <indexterm zone="functions-info">
+    <primary>pg_get_ruledef</primary>
+   </indexterm>
 
-  <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>
+   <indexterm zone="functions-info">
+    <primary>pg_get_indexdef</primary>
+   </indexterm>
 
-  <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>
+   <indexterm zone="functions-info">
+    <primary>pg_get_triggerdef</primary>
+   </indexterm>
 
-  <sect2>
-   <title>Row-wise Comparison</title>
+   <indexterm zone="functions-info">
+    <primary>pg_get_constraintdef</primary>
+   </indexterm>
 
-   <indexterm>
-    <primary>comparison</primary>
-    <secondary>of rows</secondary>
+   <indexterm zone="functions-info">
+    <primary>pg_get_expr</primary>
    </indexterm>
 
-<synopsis>
-<replaceable>row_constructor</replaceable> <replaceable>operator</replaceable> (<replaceable>subquery</replaceable>)
-</synopsis>
+   <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>
-   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.
+   <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>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 serial or bigserial 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>
-   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).
+   <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>
-  </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>
 
   <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.
+   <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>
 
-  <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>
+  <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>
 
-  <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>
+   <indexterm zone="functions-info">
+    <primary>obj_description</primary>
+   </indexterm>
 
-  <sect2>
-   <title><literal>NOT IN</literal></title>
+   <indexterm zone="functions-info">
+    <primary>col_description</primary>
+   </indexterm>
 
-<synopsis>
-<replaceable>expression</replaceable> NOT IN (<replaceable>value</replaceable><optional>, ...</optional>)
-</synopsis>
+   <indexterm zone="functions-info">
+    <primary>comment</primary>
+    <secondary sortas="database objects">about database objects</secondary>
+   </indexterm>
 
-  <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
+   <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>
 
-<synopsis>
-<replaceable>expression</replaceable> &lt;&gt; <replaceable>value1</replaceable>
-AND
-<replaceable>expression</replaceable> &lt;&gt; <replaceable>value2</replaceable>
-AND
-...
-</synopsis>
-  </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>
 
-  <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>
+     <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>
 
-  <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>
+   <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>
 
-  <sect2>
-   <title><literal>ANY</literal>/<literal>SOME</literal> (array)</title>
+   <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>
 
-<synopsis>
-<replaceable>expression</replaceable> <replaceable>operator</replaceable> ANY (<replaceable>array expression</replaceable>)
-<replaceable>expression</replaceable> <replaceable>operator</replaceable> SOME (<replaceable>array expression</replaceable>)
-</synopsis>
+ <sect1 id="functions-admin">
+  <title>System Administration Functions</title>
 
   <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).
+   <xref linkend="functions-admin-set-table"> shows the functions
+   available to query and alter run-time configuration parameters.
   </para>
 
-  <para>
-   <token>SOME</token> is a synonym for <token>ANY</token>.
-  </para>
-  </sect2>
+   <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>
 
-  <sect2>
-   <title><literal>ALL</literal> (array)</title>
+     <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>
 
-<synopsis>
-<replaceable>expression</replaceable> <replaceable>operator</replaceable> ALL (<replaceable>array expression</replaceable>)
-</synopsis>
+   <indexterm zone="functions-admin">
+    <primary>SET</primary>
+   </indexterm>
 
-  <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>
+   <indexterm zone="functions-admin">
+    <primary>SHOW</primary>
+   </indexterm>
 
-  <sect2>
-   <title>Row-wise Comparison</title>
+   <indexterm zone="functions-admin">
+    <primary>configuration</primary>
+    <secondary sortas="server">of the server</secondary>
+    <tertiary>functions</tertiary>
+   </indexterm>
 
-<synopsis>
-<replaceable>row_constructor</replaceable> <replaceable>operator</replaceable> <replaceable>row_constructor</replaceable>
-</synopsis>
+   <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');
 
-  <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>
+ current_setting
+-----------------
+ ISO, MDY
+(1 row)
+</programlisting>
+   </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>
+   <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);
 
-<synopsis>
-<replaceable>row_constructor</replaceable> IS DISTINCT FROM <replaceable>row_constructor</replaceable>
-</synopsis>
+ set_config
+------------
+ off
+(1 row)
+</programlisting>
+   </para>
 
-  <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>
+   <indexterm zone="functions-admin">
+    <primary>pg_cancel_backend</primary>
+   </indexterm>
 
-<synopsis>
-<replaceable>row_constructor</replaceable> IS NULL
-<replaceable>row_constructor</replaceable> IS NOT NULL
-</synopsis>
+   <indexterm zone="functions-admin">
+    <primary>signal</primary>
+    <secondary sortas="backend">backend processes</secondary>
+   </indexterm>
 
-  <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>
+   <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>
 
-  </sect2>
- </sect1>
+   <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>
 
- <sect1 id="functions-srf">
-  <title>Set Returning Functions</title>
+     <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>
 
-  <indexterm zone="functions-srf">
-   <primary>set returning functions</primary>
-   <secondary>functions</secondary>
-  </indexterm>
+   <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 postgres
+    processes on the server with <application>ps</>.
+   </para>
 
-  <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>
+   <indexterm zone="functions-admin">
+    <primary>pg_start_backup</primary>
+   </indexterm>
 
-  <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>
+   <indexterm zone="functions-admin">
+    <primary>pg_stop_backup</primary>
+   </indexterm>
 
-    <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>
+   <indexterm zone="functions-admin">
+    <primary>backup</primary>
+   </indexterm>
 
-     <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>
+   <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>
 
-    </tbody>
-   </tgroup>
-  </table>
+   <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>
 
-  <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)
+     <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>
 
-select * from generate_series(5,1,-2);
- generate_series
------------------
-               5
-               3
-               1
-(3 rows)
+   <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>
 
-select * from generate_series(4,3);
- generate_series
------------------
-(0 rows)
+   <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>
 
-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>
+   <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
index a09927a1ecacb1184ca129844f43869fe12628b2..5e5a923ac7ebc2252dc6e21832a89f535b514c81 100644 (file)
@@ -1,5 +1,5 @@
 <!--
-$PostgreSQL: pgsql/doc/src/sgml/ref/set.sgml,v 1.84 2003/11/29 19:51:39 pgsql Exp $
+$PostgreSQL: pgsql/doc/src/sgml/ref/set.sgml,v 1.85 2004/08/03 20:32:32 tgl Exp $
 PostgreSQL documentation
 -->
 
@@ -229,7 +229,7 @@ SELECT setseed(<replaceable>value</replaceable>);
 
   <para>
    The function <function>set_config</function> provides equivalent
-   functionality. See <xref linkend="functions-misc">.
+   functionality. See <xref linkend="functions-admin">.
   </para>
  </refsect1>
  
index 85dbfdcedcc911b65b408abdd9861a19f024abcd..cbd78a99467aafc0d7404a2f7275b3a9525a7fa7 100644 (file)
@@ -1,5 +1,5 @@
 <!--
-$PostgreSQL: pgsql/doc/src/sgml/ref/show.sgml,v 1.35 2004/01/06 17:26:23 neilc Exp $
+$PostgreSQL: pgsql/doc/src/sgml/ref/show.sgml,v 1.36 2004/08/03 20:32:32 tgl Exp $
 PostgreSQL documentation
 -->
 
@@ -130,7 +130,7 @@ SHOW ALL
 
   <para>
    The function <function>current_setting</function> produces
-   equivalent output. See <xref linkend="functions-misc">.
+   equivalent output. See <xref linkend="functions-admin">.
   </para>
  </refsect1>
 
index b0fac7452669ef6b0ff268e946442e1043f3e26b..596665800356ecfad4fa562071653f74262da071 100644 (file)
@@ -7,7 +7,7 @@
  * Portions Copyright (c) 1996-2003, PostgreSQL Global Development Group
  * Portions Copyright (c) 1994, Regents of the University of California
  *
- * $PostgreSQL: pgsql/src/backend/access/transam/xlog.c,v 1.153 2004/08/01 17:45:42 tgl Exp $
+ * $PostgreSQL: pgsql/src/backend/access/transam/xlog.c,v 1.154 2004/08/03 20:32:32 tgl Exp $
  *
  *-------------------------------------------------------------------------
  */
@@ -5048,3 +5048,233 @@ issue_xlog_fsync(void)
                        break;
        }
 }
+
+
+/*
+ * pg_start_backup: set up for taking an on-line backup dump
+ *
+ * Essentially what this does is to create a backup label file in $PGDATA,
+ * where it will be archived as part of the backup dump.  The label file
+ * contains the user-supplied label string (typically this would be used
+ * to tell where the backup dump will be stored) and the starting time and
+ * starting WAL offset for the dump.
+ */
+Datum
+pg_start_backup(PG_FUNCTION_ARGS)
+{
+       text       *backupid = PG_GETARG_TEXT_P(0);
+       text       *result;
+       char       *backupidstr;
+       XLogRecPtr      startpoint;
+       time_t stamp_time;
+       char            strfbuf[128];
+       char            labelfilename[MAXPGPATH];
+       char            xlogfilename[MAXFNAMELEN];
+       uint32          _logId;
+       uint32          _logSeg;
+       struct stat stat_buf;
+       FILE       *fp;
+
+       if (!superuser()) 
+               ereport(ERROR,
+                               (errcode(ERRCODE_INSUFFICIENT_PRIVILEGE),
+                                (errmsg("must be superuser to run a backup"))));
+       backupidstr = DatumGetCString(DirectFunctionCall1(textout,
+                                                                                                         PointerGetDatum(backupid)));
+       /*
+        * The oldest point in WAL that would be needed to restore starting from
+        * the most recent checkpoint is precisely the RedoRecPtr.
+        */
+       startpoint = GetRedoRecPtr();
+       XLByteToSeg(startpoint, _logId, _logSeg);
+       XLogFileName(xlogfilename, ThisTimeLineID, _logId, _logSeg);
+       /*
+        * We deliberately use strftime/localtime not the src/timezone functions,
+        * so that backup labels will consistently be recorded in the same
+        * timezone regardless of TimeZone setting.  This matches elog.c's
+        * practice.
+        */
+       stamp_time = time(NULL);
+       strftime(strfbuf, sizeof(strfbuf),
+                        "%Y-%m-%d %H:%M:%S %Z",
+                        localtime(&stamp_time));
+       /*
+        * Check for existing backup label --- implies a backup is already running
+        */
+       snprintf(labelfilename, MAXPGPATH, "%s/backup_label", DataDir);
+       if (stat(labelfilename, &stat_buf) != 0)
+       {
+               if (errno != ENOENT)
+                       ereport(ERROR,
+                                       (errcode_for_file_access(),
+                                        errmsg("could not stat \"%s\": %m",
+                                                       labelfilename)));
+       }
+       else
+               ereport(ERROR,
+                               (errcode(ERRCODE_OBJECT_NOT_IN_PREREQUISITE_STATE),
+                                errmsg("a backup is already in progress"),
+                                errhint("If you're sure there is no backup in progress, remove file \"%s\" and try again.",
+                                                labelfilename)));
+       /*
+        * Okay, write the file
+        */
+       fp = AllocateFile(labelfilename, "w");
+       if (!fp)
+               ereport(ERROR,
+                               (errcode_for_file_access(),
+                                errmsg("could not create file \"%s\": %m",
+                                               labelfilename)));
+       fprintf(fp, "START WAL LOCATION: %X/%X (file %s)\n",
+                       startpoint.xlogid, startpoint.xrecoff, xlogfilename);
+       fprintf(fp, "START TIME: %s\n", strfbuf);
+       fprintf(fp, "LABEL: %s\n", backupidstr);
+       if (fflush(fp) || ferror(fp) || FreeFile(fp))
+               ereport(ERROR,
+                               (errcode_for_file_access(),
+                                errmsg("could not write file \"%s\": %m",
+                                               labelfilename)));
+       /*
+        * We're done.  As a convenience, return the starting WAL offset.
+        */
+       snprintf(xlogfilename, sizeof(xlogfilename), "%X/%X",
+                        startpoint.xlogid, startpoint.xrecoff);
+       result = DatumGetTextP(DirectFunctionCall1(textin,
+                                                                                          CStringGetDatum(xlogfilename)));
+       PG_RETURN_TEXT_P(result);
+}
+
+/*
+ * pg_stop_backup: finish taking an on-line backup dump
+ *
+ * We remove the backup label file created by pg_start_backup, and instead
+ * create a backup history file in pg_xlog (whence it will immediately be
+ * archived).  The backup history file contains the same info found in
+ * the label file, plus the backup-end time and WAL offset.
+ */
+Datum
+pg_stop_backup(PG_FUNCTION_ARGS)
+{
+       text       *result;
+       XLogCtlInsert *Insert = &XLogCtl->Insert;
+       XLogRecPtr      startpoint;
+       XLogRecPtr      stoppoint;
+       time_t stamp_time;
+       char            strfbuf[128];
+       char            labelfilename[MAXPGPATH];
+       char            histfilename[MAXPGPATH];
+       char            startxlogfilename[MAXFNAMELEN];
+       char            stopxlogfilename[MAXFNAMELEN];
+       uint32          _logId;
+       uint32          _logSeg;
+       FILE       *lfp;
+       FILE       *fp;
+       char            ch;
+       int                     ich;
+
+       if (!superuser()) 
+               ereport(ERROR,
+                               (errcode(ERRCODE_INSUFFICIENT_PRIVILEGE),
+                                (errmsg("must be superuser to run a backup"))));
+       /*
+        * Get the current end-of-WAL position; it will be unsafe to use this
+        * dump to restore to a point in advance of this time.
+        */
+       LWLockAcquire(WALInsertLock, LW_EXCLUSIVE);
+       INSERT_RECPTR(stoppoint, Insert, Insert->curridx);
+       LWLockRelease(WALInsertLock);
+
+       XLByteToSeg(stoppoint, _logId, _logSeg);
+       XLogFileName(stopxlogfilename, ThisTimeLineID, _logId, _logSeg);
+       /*
+        * We deliberately use strftime/localtime not the src/timezone functions,
+        * so that backup labels will consistently be recorded in the same
+        * timezone regardless of TimeZone setting.  This matches elog.c's
+        * practice.
+        */
+       stamp_time = time(NULL);
+       strftime(strfbuf, sizeof(strfbuf),
+                        "%Y-%m-%d %H:%M:%S %Z",
+                        localtime(&stamp_time));
+       /*
+        * Open the existing label file
+        */
+       snprintf(labelfilename, MAXPGPATH, "%s/backup_label", DataDir);
+       lfp = AllocateFile(labelfilename, "r");
+       if (!lfp)
+       {
+               if (errno != ENOENT)
+                       ereport(ERROR,
+                                       (errcode_for_file_access(),
+                                        errmsg("could not read file \"%s\": %m",
+                                                       labelfilename)));
+               ereport(ERROR,
+                               (errcode(ERRCODE_OBJECT_NOT_IN_PREREQUISITE_STATE),
+                                errmsg("a backup is not in progress")));
+       }
+       /*
+        * Read and parse the START WAL LOCATION line (this code is pretty
+        * crude, but we are not expecting any variability in the file format).
+        */
+       if (fscanf(lfp, "START WAL LOCATION: %X/%X (file %24s)%c",
+                          &startpoint.xlogid, &startpoint.xrecoff, startxlogfilename,
+                          &ch) != 4 || ch != '\n')
+               ereport(ERROR,
+                               (errcode(ERRCODE_OBJECT_NOT_IN_PREREQUISITE_STATE),
+                                errmsg("invalid data in file \"%s\"", labelfilename)));
+       /*
+        * Write the backup history file
+        */
+       XLByteToSeg(startpoint, _logId, _logSeg);
+       BackupHistoryFilePath(histfilename, ThisTimeLineID, _logId, _logSeg,
+                                                 startpoint.xrecoff % XLogSegSize);
+       fp = AllocateFile(histfilename, "w");
+       if (!fp)
+               ereport(ERROR,
+                               (errcode_for_file_access(),
+                                errmsg("could not create file \"%s\": %m",
+                                               histfilename)));
+       fprintf(fp, "START WAL LOCATION: %X/%X (file %s)\n",
+                       startpoint.xlogid, startpoint.xrecoff, startxlogfilename);
+       fprintf(fp, "STOP WAL LOCATION: %X/%X (file %s)\n",
+                       stoppoint.xlogid, stoppoint.xrecoff, stopxlogfilename);
+       /* transfer start time and label lines from label to history file */
+       while ((ich = fgetc(lfp)) != EOF)
+               fputc(ich, fp);
+       fprintf(fp, "STOP TIME: %s\n", strfbuf);
+       if (fflush(fp) || ferror(fp) || FreeFile(fp))
+               ereport(ERROR,
+                               (errcode_for_file_access(),
+                                errmsg("could not write file \"%s\": %m",
+                                               histfilename)));
+       /*
+        * Close and remove the backup label file
+        */
+       if (ferror(lfp) || FreeFile(lfp))
+               ereport(ERROR,
+                               (errcode_for_file_access(),
+                                errmsg("could not read file \"%s\": %m",
+                                               labelfilename)));
+       if (unlink(labelfilename) != 0)
+               ereport(ERROR,
+                               (errcode_for_file_access(),
+                                errmsg("could not remove file \"%s\": %m",
+                                               labelfilename)));
+       /*
+        * Notify archiver that history file may be archived immediately
+        */
+       if (XLogArchivingActive())
+       {
+               BackupHistoryFileName(histfilename, ThisTimeLineID, _logId, _logSeg,
+                                                         startpoint.xrecoff % XLogSegSize);
+               XLogArchiveNotify(histfilename);
+       }
+       /*
+        * We're done.  As a convenience, return the ending WAL offset.
+        */
+       snprintf(stopxlogfilename, sizeof(stopxlogfilename), "%X/%X",
+                        stoppoint.xlogid, stoppoint.xrecoff);
+       result = DatumGetTextP(DirectFunctionCall1(textin,
+                                                                                          CStringGetDatum(stopxlogfilename)));
+       PG_RETURN_TEXT_P(result);
+}
index a40389633319ea9a1a9cd03f7279a032009fc37b..960ece7583199f56e915a4f065d67f6f303cf2a0 100644 (file)
@@ -19,7 +19,7 @@
  *
  *
  * IDENTIFICATION
- *       $PostgreSQL: pgsql/src/backend/postmaster/pgarch.c,v 1.3 2004/08/01 17:45:43 tgl Exp $
+ *       $PostgreSQL: pgsql/src/backend/postmaster/pgarch.c,v 1.4 2004/08/03 20:32:33 tgl Exp $
  *
  *-------------------------------------------------------------------------
  */
@@ -64,8 +64,8 @@
  * ----------
  */
 #define MIN_XFN_CHARS  16
-#define MAX_XFN_CHARS  24
-#define VALID_XFN_CHARS        "0123456789ABCDEF.history"
+#define MAX_XFN_CHARS  40
+#define VALID_XFN_CHARS        "0123456789ABCDEF.history.backup"
 
 #define NUM_ARCHIVE_RETRIES 3
 
index 0cc315c6205e2d8717c93716e702146e65646ecc..8bf989a86584901a46d68e028d69aeabf6393534 100644 (file)
@@ -8,7 +8,7 @@
  *
  *
  * IDENTIFICATION
- *       $PostgreSQL: pgsql/src/backend/utils/adt/misc.c,v 1.35 2004/07/02 18:59:22 joe Exp $
+ *       $PostgreSQL: pgsql/src/backend/utils/adt/misc.c,v 1.36 2004/08/03 20:32:33 tgl Exp $
  *
  *-------------------------------------------------------------------------
  */
@@ -27,6 +27,8 @@
 #include "catalog/pg_type.h"
 #include "catalog/pg_tablespace.h"
 
+#define atooid(x)  ((Oid) strtoul((x), NULL, 10))
+
 
 /*
  * Check if data is Null
@@ -67,8 +69,7 @@ current_database(PG_FUNCTION_ARGS)
 
 
 /*
- * Functions to terminate a backend or cancel a query running on
- * a different backend.
+ * Functions to send signals to other backends.
  */
 
 static int pg_signal_backend(int pid, int sig) 
@@ -76,14 +77,16 @@ static int pg_signal_backend(int pid, int sig)
        if (!superuser()) 
                ereport(ERROR,
                                (errcode(ERRCODE_INSUFFICIENT_PRIVILEGE),
-                                (errmsg("only superuser can signal other backends"))));
+                                (errmsg("must be superuser to signal other server processes"))));
        
        if (!IsBackendPid(pid))
        {
-               /* This is just a warning so a loop-through-resultset will not abort
-                * if one backend terminated on it's own during the run */
+               /*
+                * This is just a warning so a loop-through-resultset will not abort
+                * if one backend terminated on it's own during the run
+                */
                ereport(WARNING,
-                               (errmsg("pid %i is not a postgresql backend",pid)));
+                               (errmsg("PID %d is not a PostgreSQL server process", pid)));
                return 0;
        }
 
@@ -91,24 +94,32 @@ static int pg_signal_backend(int pid, int sig)
        {
                /* Again, just a warning to allow loops */
                ereport(WARNING,
-                               (errmsg("failed to send signal to backend %i: %m",pid)));
+                               (errmsg("could not send signal to process %d: %m",pid)));
                return 0;
        }
        return 1;
 }
 
 Datum
-pg_terminate_backend(PG_FUNCTION_ARGS)
+pg_cancel_backend(PG_FUNCTION_ARGS)
 {
-       PG_RETURN_INT32(pg_signal_backend(PG_GETARG_INT32(0),SIGTERM));
+       PG_RETURN_INT32(pg_signal_backend(PG_GETARG_INT32(0),SIGINT));
 }
 
+#ifdef NOT_USED
+
+/* Disabled in 8.0 due to reliability concerns; FIXME someday */
+
 Datum
-pg_cancel_backend(PG_FUNCTION_ARGS)
+pg_terminate_backend(PG_FUNCTION_ARGS)
 {
-       PG_RETURN_INT32(pg_signal_backend(PG_GETARG_INT32(0),SIGINT));
+       PG_RETURN_INT32(pg_signal_backend(PG_GETARG_INT32(0),SIGTERM));
 }
 
+#endif
+
+
+/* Function to find out which databases make use of a tablespace */
 
 typedef struct 
 {
@@ -140,9 +151,8 @@ Datum pg_tablespace_databases(PG_FUNCTION_ARGS)
                if (tablespaceOid == GLOBALTABLESPACE_OID)
                {
                        fctx->dirdesc = NULL;
-                       ereport(NOTICE,
-                                       (errcode(ERRCODE_WARNING),
-                                        errmsg("global tablespace never has databases.")));
+                       ereport(WARNING,
+                                       (errmsg("global tablespace never has databases")));
                }
                else
                {
@@ -154,10 +164,17 @@ Datum pg_tablespace_databases(PG_FUNCTION_ARGS)
                
                        fctx->dirdesc = AllocateDir(fctx->location);
 
-                       if (!fctx->dirdesc)  /* not a tablespace */
-                               ereport(NOTICE,
-                                               (errcode(ERRCODE_WARNING),
-                                                errmsg("%d is no tablespace oid.", tablespaceOid)));
+                       if (!fctx->dirdesc)
+                       {
+                               /* the only expected error is ENOENT */
+                               if (errno != ENOENT)
+                                       ereport(ERROR,
+                                                       (errcode_for_file_access(),
+                                                        errmsg("could not open directory \"%s\": %m",
+                                                                       fctx->location)));
+                               ereport(WARNING,
+                                               (errmsg("%u is not a tablespace oid", tablespaceOid)));
+                       }
                }
                funcctx->user_fctx = fctx;
                MemoryContextSwitchTo(oldcontext);
@@ -174,27 +191,30 @@ Datum pg_tablespace_databases(PG_FUNCTION_ARGS)
                char *subdir;
                DIR *dirdesc;
 
-               Oid datOid = atol(de->d_name);
+               Oid datOid = atooid(de->d_name);
+               /* this test skips . and .., but is awfully weak */
                if (!datOid)
                        continue;
 
+               /* if database subdir is empty, don't report tablespace as used */
+
                /* size = path length + dir sep char + file name + terminator */
                subdir = palloc(strlen(fctx->location) + 1 + strlen(de->d_name) + 1);
                sprintf(subdir, "%s/%s", fctx->location, de->d_name);
                dirdesc = AllocateDir(subdir);
-               if (dirdesc)
-               {
-                       while ((de = readdir(dirdesc)) != 0)
-                       {
-                               if (strcmp(de->d_name, ".") && strcmp(de->d_name, ".."))
-                                       break;
-                       }
-                       pfree(subdir);
-                       FreeDir(dirdesc);
+               pfree(subdir);
+               if (!dirdesc)
+                       continue;                       /* XXX more sloppiness */
 
-                       if (!de)   /* database subdir is empty; don't report tablespace as used */
-                               continue;
+               while ((de = readdir(dirdesc)) != 0)
+               {
+                       if (strcmp(de->d_name, ".") != 0 && strcmp(de->d_name, "..") != 0)
+                               break;
                }
+               FreeDir(dirdesc);
+
+               if (!de)
+                       continue;                       /* indeed, nothing in it */
 
                SRF_RETURN_NEXT(funcctx, ObjectIdGetDatum(datOid));
        }
index 09877bf64be89e12416d8af8653a64c27086801e..89c37b7d66a1738d85ad9db834fe5c0ba0300d3e 100644 (file)
  * Portions Copyright (c) 1996-2003, PostgreSQL Global Development Group
  * Portions Copyright (c) 1994, Regents of the University of California
  *
- * $PostgreSQL: pgsql/src/include/access/xlog_internal.h,v 1.1 2004/07/21 22:31:25 tgl Exp $
+ * $PostgreSQL: pgsql/src/include/access/xlog_internal.h,v 1.2 2004/08/03 20:32:34 tgl Exp $
  */
 #ifndef XLOG_INTERNAL_H
 #define XLOG_INTERNAL_H
 
 #include "access/xlog.h"
+#include "fmgr.h"
 #include "storage/block.h"
 #include "storage/relfilenode.h"
 
@@ -177,7 +178,7 @@ typedef XLogLongPageHeaderData *XLogLongPageHeader;
  * These macros encapsulate knowledge about the exact layout of XLog file
  * names, timeline history file names, and archive-status file names.
  */
-#define MAXFNAMELEN            32
+#define MAXFNAMELEN            64
 
 #define XLogFileName(fname, tli, log, seg)     \
        snprintf(fname, MAXFNAMELEN, "%08X%08X%08X", tli, log, seg)
@@ -194,6 +195,12 @@ typedef XLogLongPageHeaderData *XLogLongPageHeader;
 #define StatusFilePath(path, xlog, suffix)     \
        snprintf(path, MAXPGPATH, "%s/archive_status/%s%s", XLogDir, xlog, suffix)
 
+#define BackupHistoryFileName(fname, tli, log, seg, offset)    \
+       snprintf(fname, MAXFNAMELEN, "%08X%08X%08X.%08X.backup", tli, log, seg, offset)
+
+#define BackupHistoryFilePath(path, tli, log, seg, offset)     \
+       snprintf(path, MAXPGPATH, "%s/%08X%08X%08X.%08X.backup", XLogDir, tli, log, seg, offset)
+
 extern char XLogDir[MAXPGPATH];
 
 /*
@@ -221,4 +228,10 @@ typedef struct RmgrData
 
 extern const RmgrData RmgrTable[];
 
+/*
+ * These aren't in xlog.h because I'd rather not include fmgr.h there.
+ */
+extern Datum pg_start_backup(PG_FUNCTION_ARGS);
+extern Datum pg_stop_backup(PG_FUNCTION_ARGS);
+
 #endif   /* XLOG_INTERNAL_H */
index d7d180eaf5173f54032c3f1fe3c46820f6dd7e7a..0d5ac8f13c578c392149fc40f1c22d7fe200c9e4 100644 (file)
@@ -37,7 +37,7 @@
  * Portions Copyright (c) 1996-2003, PostgreSQL Global Development Group
  * Portions Copyright (c) 1994, Regents of the University of California
  *
- * $PostgreSQL: pgsql/src/include/catalog/catversion.h,v 1.247 2004/07/21 20:43:53 momjian Exp $
+ * $PostgreSQL: pgsql/src/include/catalog/catversion.h,v 1.248 2004/08/03 20:32:35 tgl Exp $
  *
  *-------------------------------------------------------------------------
  */
@@ -53,6 +53,6 @@
  */
 
 /*                                                     yyyymmddN */
-#define CATALOG_VERSION_NO     200407211
+#define CATALOG_VERSION_NO     200408031
 
 #endif
index 646fa73dd15aae4eaff44153d0ddb32b598c40fd..21bd60fb94699d648de250c005043bc5ce9e2ca6 100644 (file)
@@ -7,7 +7,7 @@
  * Portions Copyright (c) 1996-2003, PostgreSQL Global Development Group
  * Portions Copyright (c) 1994, Regents of the University of California
  *
- * $PostgreSQL: pgsql/src/include/catalog/pg_proc.h,v 1.342 2004/07/12 20:23:53 momjian Exp $
+ * $PostgreSQL: pgsql/src/include/catalog/pg_proc.h,v 1.343 2004/08/03 20:32:35 tgl Exp $
  *
  * NOTES
  *       The script catalog/genbki.sh reads this file and generates .bki
@@ -2815,11 +2815,6 @@ DESCR("Statistics: Blocks fetched for database");
 DATA(insert OID = 1945 (  pg_stat_get_db_blocks_hit            PGNSP PGUID 12 f f t f s 1 20 "26" _null_       pg_stat_get_db_blocks_hit - _null_ ));
 DESCR("Statistics: Blocks found in cache for database");
 
-DATA(insert OID = 2171 ( pg_terminate_backend           PGNSP PGUID 12 f f t f s 1 23 "23" _null_ pg_terminate_backend - _null_ ));
-DESCR("Terminate a backend process");
-DATA(insert OID = 2172 ( pg_cancel_backend              PGNSP PGUID 12 f f t f s 1 23 "23" _null_ pg_cancel_backend - _null_ ));
-DESCR("Cancel running query on a backend process");
-
 DATA(insert OID = 1946 (  encode                                               PGNSP PGUID 12 f f t f i 2 25 "17 25" _null_  binary_encode - _null_ ));
 DESCR("Convert bytea value into some ascii-only text string");
 DATA(insert OID = 1947 (  decode                                               PGNSP PGUID 12 f f t f i 2 17 "25 25" _null_  binary_decode - _null_ ));
@@ -2993,10 +2988,18 @@ DATA(insert OID = 2082 (  pg_operator_is_visible        PGNSP PGUID 12 f f t f s 1 16 "
 DESCR("is operator visible in search path?");
 DATA(insert OID = 2083 (  pg_opclass_is_visible                PGNSP PGUID 12 f f t f s 1 16 "26" _null_       pg_opclass_is_visible - _null_ ));
 DESCR("is opclass visible in search path?");
-DATA(insert OID = 2093 (  pg_conversion_is_visible             PGNSP PGUID 12 f f t f s 1 16 "26" _null_       pg_conversion_is_visible - _null_ ));
+DATA(insert OID = 2093 (  pg_conversion_is_visible     PGNSP PGUID 12 f f t f s 1 16 "26" _null_       pg_conversion_is_visible - _null_ ));
 DESCR("is conversion visible in search path?");
 
 
+DATA(insert OID = 2171 ( pg_cancel_backend             PGNSP PGUID 12 f f t f v 1 23 "23" _null_ pg_cancel_backend - _null_ ));
+DESCR("Cancel a server process' current query");
+DATA(insert OID = 2172 ( pg_start_backup               PGNSP PGUID 12 f f t f v 1 25 "25" _null_ pg_start_backup - _null_ ));
+DESCR("Prepare for taking an online backup");
+DATA(insert OID = 2173 ( pg_stop_backup                        PGNSP PGUID 12 f f t f v 0 25 "" _null_ pg_stop_backup - _null_ ));
+DESCR("Finish taking an online backup");
+
+
 /* Aggregates (moved here from pg_aggregate for 7.3) */
 
 DATA(insert OID = 2100 (  avg                          PGNSP PGUID 12 t f f f i 1 1700 "20" _null_  aggregate_dummy - _null_ ));
index 3e9f58e7f26970702078dc6ec44348fc63cbbd84..09d91d985c9f6cb0885038c99430843432e2c899 100644 (file)
@@ -7,7 +7,7 @@
  * Portions Copyright (c) 1996-2003, PostgreSQL Global Development Group
  * Portions Copyright (c) 1994, Regents of the University of California
  *
- * $PostgreSQL: pgsql/src/include/utils/builtins.h,v 1.246 2004/07/12 20:23:59 momjian Exp $
+ * $PostgreSQL: pgsql/src/include/utils/builtins.h,v 1.247 2004/08/03 20:32:36 tgl Exp $
  *
  *-------------------------------------------------------------------------
  */
@@ -360,7 +360,6 @@ extern Datum float84ge(PG_FUNCTION_ARGS);
 extern Datum nullvalue(PG_FUNCTION_ARGS);
 extern Datum nonnullvalue(PG_FUNCTION_ARGS);
 extern Datum current_database(PG_FUNCTION_ARGS);
-extern Datum pg_terminate_backend(PG_FUNCTION_ARGS);
 extern Datum pg_cancel_backend(PG_FUNCTION_ARGS);
 extern Datum pg_tablespace_databases(PG_FUNCTION_ARGS);