<!--
$Header: /cvsroot/pgsql/doc/src/sgml/runtime.sgml,v 1.113 2002/04/15 22:33:20 tgl Exp $
-->

<Chapter Id="runtime">
 <Title>Server Run-time Environment</Title>

 <Para>
  This chapter discusses how to set up and run the database server
  and the interactions with the operating system.
 </para>

 <sect1 id="postgres-user">
  <title>The <productname>PostgreSQL</productname> user account</title>

  <indexterm>
   <primary>postgres user</primary>
  </indexterm>

  <para>
   As with any other server daemon that is connected to outside world,
   it is advisable to run <productname>PostgreSQL</productname> under a
   separate user account. This user account should only own the data
   that is managed by the server, and should not be shared with other
   daemons. (For example, using the user <quote>nobody</quote> is a bad
   idea.) It is not advisable to install executables owned by
   this user because compromised systems could then modify their own 
   binaries.
  </para>

  <para>
   To add a Unix user account to your system, look for a command
   <command>useradd</command> or <command>adduser</command>. The user
   name <systemitem>postgres</systemitem> is often used but is by no
   means required.
  </para>
 </sect1>

 <sect1 id="creating-cluster">
  <title>Creating a database cluster</title>

  <indexterm>
   <primary>database cluster</primary>
  </indexterm>

  <indexterm>
   <primary>data area</primary>
   <see>database cluster</see>
  </indexterm>

  <para>
   Before you can do anything, you must initialize a database storage
   area on disk. We call this a <firstterm>database cluster</firstterm>.
   (<acronym>SQL</acronym> uses the term catalog cluster instead.) A
   database cluster is a collection of databases is accessible by a
   single instance of a running database server. After initialization, a
   database cluster will contain a database named
   <literal>template1</literal>. As the name suggests, this will be used
   as a template for subsequently created databases; it should not be
   used for actual work.
  </para>

  <para>
   In file system terms, a database cluster will be a single directory
   under which all data will be stored. We call this the <firstterm>data
   directory</firstterm> or <firstterm>data area</firstterm>. It is
   completely up to you where you choose to store your data.  There is no
   default, although locations such as
   <filename>/usr/local/pgsql/data</filename> or
   <filename>/var/lib/pgsql/data</filename> are popular. To initialize a
   database cluster, use the command <command>initdb</command>, which is
   installed with <productname>PostgreSQL</productname>. The desired
   file system location of your database system is indicated by the
   <option>-D</option> option, for example
<screen>
<prompt>$</> <userinput>initdb -D /usr/local/pgsql/data</userinput>
</screen>
   Note that you must execute this command while logged into the
   <productname>PostgreSQL</productname> user account, which is
   described in the previous section.
  </para>

  <tip>
   <para>
    <indexterm>
     <primary><envar>PGDATA</envar></primary>
    </indexterm>
    As an alternative to the <option>-D</option> option, you can set
    the environment variable <envar>PGDATA</envar>.
   </para>
  </tip>

  <para>
   <command>initdb</command> will attempt to create the directory you
   specify if it does not already exist. It is likely that it will not
   have the permission to do so (if you followed our advice and created
   an unprivileged account). In that case you should create the
   directory yourself (as root) and change the owner to be the
   <productname>PostgreSQL</productname> user. Here is how this might
   be done:
<screen>
root# <userinput>mkdir /usr/local/pgsql/data</userinput>
root# <userinput>chown postgres /usr/local/pgsql/data</userinput>
root# <userinput>su postgres</userinput>
postgres$ <userinput>initdb -D /usr/local/pgsql/data</userinput>
</screen>
  </para>

  <para>
   <command>initdb</command> will refuse to run if the data directory
   looks like it it has already been initialized.</para>

  <para>
   Because the data directory contains all the data stored in the
   database, it is essential that it be secured from unauthorized
   access. <command>initdb</command> therefore revokes access
   permissions from everyone but the
   <productname>PostgreSQL</productname> user.
  </para>

  <para>
   However, while the directory contents are secure, the default
   <filename>pg_hba.conf</filename> authentication method of
   <literal>trust</literal> allows any local user to connect to the
   database and even become the database superuser. If you don't trust
   other local users, we recommend you use <command>initdb</command>'s
   <option>-W</option> or <option>--pwprompt</option> option to assign a
   password to the database superuser. After <command>initdb</command>,
   modify <filename>pg_hba.conf</filename> to use <literal>md5</> or
   <literal>password</> instead of <literal>trust</> authentication
   <emphasis>before</> you start the server for the first time. (Other,
   approaches include using <literal>ident</literal> authentication or
   file system permissions to restrict connections. See <xref
   linkend="client-authentication"> for more information.
  </para>

  <para>
   <indexterm><primary>locale</></>
   <indexterm><primary>LC_COLLATE</></>
   <command>initdb</command> also initializes the default locale for
   the database cluster.  Normally, it will just take the locale
   settings in the environment and apply them to the initialized
   database.  It is possible to specify a different locale for the
   database; more information about that can be found in <xref
   linkend="locale">.  One surprise you might encounter while running
   <command>initdb</command> is a notice similar to this:
<screen>
WARNING:  Initializing database with en_US collation order.
        This locale setting will prevent use of index optimization for
        LIKE and regexp searches.  If you are concerned about speed of
        such queries, you may wish to set LC_COLLATE to "C" and
        re-initdb.  For more information see the Administrator's Guide.
</screen>
   This is intended to warn you that the currently selected locale
   will cause indexes to be sorted in an order that prevents them from
   being used for LIKE and regular-expression searches. If you need
   good performance in such searches, you should set your current
   locale to <literal>C</> and re-run <command>initdb</command>, e.g.,
   by running <literal>initdb --lc-collate=C</literal>. The sort
   order used within a particular database cluster is set by
   <command>initdb</command> and cannot be changed later, short of
   dumping all data, rerunning <command>initdb</command>, and
   reloading the data. So it's important to make this choice correctly
   the first time.
  </para>
 </sect1>

 <sect1 id="postmaster-start">
  <title>Starting the database server</title>

  <para>
   <indexterm>
    <primary>postmaster</primary>
   </indexterm>
   Before anyone can access the database, you must start the database
   server. The database server is called
   <firstterm>postmaster</firstterm>. The postmaster must know where to
   find the data it is supposed to use. This is done with the
   <option>-D</option> option. Thus, the simplest way to start the
   server is:
<screen>
$ <userinput>postmaster -D /usr/local/pgsql/data</userinput>
</screen>
   which will leave the server running in the foreground. This must be
   done while logged into the <productname>PostgreSQL</productname> user
   account. Without <option>-D</option>, the server will try to use
   the data directory in the environment variable <envar>PGDATA</envar>.
   If neither of these succeed, it will fail.
  </para>

  <para>
   To start the <application>postmaster</application> in the
   background, use the usual shell syntax:
<screen>
$ <userinput>postmaster -D /usr/local/pgsql/data &gt; logfile 2&gt;&amp;1 &amp;</userinput>
</screen>
   It is an important to store the server's <systemitem>stdout</> and
   <systemitem>stderr</> output somewhere, as shown above. It will help
   for auditing purposes and to diagnose problems. (See <xref
   linkend="logfile-maintenance"> for a more thorough discussion of log
   file handling.)
  </para>

  <para>
   <indexterm>
    <primary>TCP/IP</primary>
   </indexterm>
   The postmaster also takes a number of other command line options. For
   more information, see the reference page and <xref
   linkend="runtime-config"> below. In particular, in order for the
   server to accept TCP/IP connections (rather than just Unix domain
   socket ones), you must specify the <option>-i</option> option.
  </para>

  <para>
   <indexterm>
    <primary>pg_ctl</primary>
   </indexterm>
   This shell syntax can get tedious quickly.  Therefore the shell
   script wrapper <application>pg_ctl</application> is provided to
   simplify some tasks.  For example:
<programlisting>
pg_ctl start -l logfile
</programlisting>
   will start the server in the background and put the output into the
   named log file. The <option>-D</option> option has the same meaning
   here as in the postmaster. <application>pg_ctl</application> is also
   capable of stopping the server.
  </para>

  <para>
   Normally, you will want to start the database server when the
   computer boots. Auto-start scripts are operating-system specific.
   There are a few distributed with
   <productname>PostgreSQL</productname> in the
   <filename>/contrib/start-scripts</> directory. This may require root
   privileges.
  </para>

  <para>
   Different systems have different conventions for starting up daemons
   at boot time. Many systems have a file
   <filename>/etc/rc.local</filename> or
   <filename>/etc/rc.d/rc.local</filename>. Others use
   <filename>rc.d</> directories. Whatever you do, the server must be
   run by the <productname>PostgreSQL</productname> user account
   <emphasis>and not by root</emphasis> or any other user. Therefore you
   probably should form your commands using <literal>su -c '...'
   postgres</literal>.  For example:
<programlisting>
su -c 'pg_ctl start -D /usr/local/pgsql/data -l serverlog' postgres
</programlisting>
  </para>

  <para>
   Here are a few more operating system specific suggestions. (Always
   replace these with the proper installation directory and the user
   name.)

   <itemizedlist>
    <listitem>
     <para>
      For <productname>FreeBSD</productname>, look at the file
      <filename>contrib/start-scripts/freebsd</filename> in the
      <productname>PostgreSQL</productname> source distribution.
      <indexterm><primary>FreeBSD</></>
     </para>
    </listitem>

    <listitem>
     <para>
      On <productname>OpenBSD</productname>, add the following lines
      to the file <filename>/etc/rc.local</filename>:
      <indexterm><primary>OpenBSD</></>
<programlisting>
if [ -x /usr/local/pgsql/bin/pg_ctl -a -x /usr/local/pgsql/bin/postmaster ]; then
    su - -c '/usr/local/pgsql/bin/pg_ctl start -l /var/postgresql/log -s' postgres
    echo -n ' postgresql'
fi
</programlisting>
     </para>
    </listitem>

    <listitem>
     <para>
      On <productname>Linux</productname> systems either add
      <indexterm><primary>Linux</></>
<programlisting>
/usr/local/pgsql/bin/pg_ctl start -l logfile -D /usr/local/pgsql/data
</programlisting>
      to <filename>/etc/rc.d/rc.local</filename> or look at the file
      <filename>contrib/start-scripts/linux</filename> in the
      <productname>PostgreSQL</productname> source distribution.
     </para>
    </listitem>

    <listitem>
     <para>
      On <productname>NetBSD</productname>, either use the
      <productname>FreeBSD</productname> or
      <productname>Linux</productname> start scripts, depending on
      preference. <indexterm><primary>NetBSD</></>
     </para>
    </listitem>

    <listitem>
     <para>
      On <productname>Solaris</productname>, create a file called
      <filename>/etc/init.d/postgresql</filename> which should contain
      the following line:
      <indexterm><primary>Solaris</></>
<programlisting>
su - postgres -c "/usr/local/pgsql/bin/pg_ctl start -l logfile -D /usr/local/pgsql/data"
</programlisting>
      Then, create a symbolic link to it in <filename>/etc/rc3.d</> as
      <literal>S99postgresql</>.
     </para>
    </listitem>
   </itemizedlist>

  </para>

   <para>
    While the <application>postmaster</application> is running, its
    <acronym>PID</acronym> is in the file
    <filename>postmaster.pid</filename> in the data directory. This is
    used to prevent multiple postmasters running in the same data
    directory, and can also be used for shutting down the postmaster.
   </para>

   <sect2 id="postmaster-start-failures">
    <title>Server Start-up Failures</title>

    <para>
     There are several common reasons the postmaster might fail to
     start. Check the postmaster's log file, or start it by hand
     (without redirecting standard output or standard error) and see
     what error messages appear. Some of the error messages are
     self-explanatory, but some are not, as shown below:
    </para>

    <para>
<screen>
FATAL: StreamServerPort: bind() failed: Address already in use
        Is another postmaster already running on that port?
</screen>
     This usually means just what it suggests: you tried to start
     another postmaster on the same port where one is already running.
     However, if the kernel error message is not <computeroutput>Address
     already in use</computeroutput> or some variant of that, there may
     be a different problem. For example, trying to start a postmaster
     on a reserved port number may draw something like:
<screen>
$ <userinput>postmaster -i -p 666</userinput>
FATAL: StreamServerPort: bind() failed: Permission denied
        Is another postmaster already running on that port?
</screen>
    </para>

    <para>
     A message like:
<screen>
IpcMemoryCreate: shmget(key=5440001, size=83918612, 01600) failed: Invalid argument
FATAL 1:  ShmemCreate: cannot create region
</screen>
     probably means your kernel's limit on the size of shared memory is
     smaller than the buffer area <productname>PostgreSQL</productname>
     is trying to create (83918612 bytes in this example). Or it could
     mean that you don't have System-V-style shared memory support
     configured into your kernel at all. As a temporary workaround, you
     can try starting the postmaster with a smaller-than-normal number
     of buffers (<option>-B</option> switch). You will eventually want
     to reconfigure your kernel to increase the allowed shared memory
     size. You may see this message when trying to start multiple
     postmasters on the same machine if their total space requested
     exceeds the kernel limit.
    </para>

    <para>
     An error like:
<screen>
IpcSemaphoreCreate: semget(key=5440026, num=16, 01600) failed: No space left on device
</screen>
     does <emphasis>not</emphasis> mean you've run out of disk space. It
     means your kernel's limit on the number of System V semaphores is
     smaller than the number <productname>PostgreSQL</productname> wants
     to create. As above, you may be able to work around the problem by
     starting the postmaster with a reduced number of backend processes
     (<option>-N</option> switch), but you'll eventually want to
     increase the kernel limit.
    </para>

    <para>
     If you get an <quote>illegal system call</> error, it is likely
     shared memory or semaphores are not supported in your kernel at
     all. In that case your only option is to reconfigure the kernel to
     enable these features.
    </para>

    <para>
     Details about configuring <systemitem class="osname">System V</>
     <acronym>IPC</> facilities are given in <xref linkend="sysvipc">.
    </para>
   </sect2>

   <sect2 id="client-connection-problems">
    <title>Client Connection Problems</title>

    <para>
     Although the error conditions possible on the client side are quite
     varied and application-dependent, a few of them might be directly
     related to how the server was started up. Conditions other than
     those shown below should be documented with the respective client
     application.
    </para>

    <para>
<screen>
psql: could not connect to server: Connection refused
        Is the server running on host server.joe.com and accepting
        TCP/IP connections on port 5432?
</screen>
     This is the generic <quote>I couldn't find a server to talk
     to</quote> failure. It looks like the above when TCP/IP
     communication is attempted. A common mistake is to forget the
     <option>-i</option> option to allow the postmaster to accept TCP/IP
     connections.
    </para>

    <para>
     Alternatively, you'll get this when attempting Unix-socket
     communication to a local postmaster:
<screen>
psql: could not connect to server: Connection refused
        Is the server running locally and accepting
        connections on Unix domain socket "/tmp/.s.PGSQL.5432"?
</screen>
    </para>

    <para>
     The last line is useful in verifying that the client is trying to
     connect to the right place. If there is in fact no postmaster
     running there, the kernel error message will typically be either
     <computeroutput>Connection refused</computeroutput> or
     <computeroutput>No such file or directory</computeroutput>, as
     illustrated. (It is important to realize that
     <computeroutput>Connection refused</computeroutput> in this context
     does <emphasis>not</emphasis> mean that the postmaster got your
     connection request and rejected it -- that case will produce a
     different message, as shown in <xref
     linkend="client-authentication-problems">.) Other error messages
     such as <computeroutput>Connection timed out</computeroutput> may
     indicate more fundamental problems, like lack of network
     connectivity.
    </para>
   </sect2>
  </sect1>

  <sect1 id="runtime-config">
   <Title>Run-time configuration</Title>

   <indexterm>
    <primary>configuration</primary>
    <secondary>server</secondary>
   </indexterm>

   <para>
    There are a lot of configuration parameters that affect the behavior
    of the database system. Here we describe how to set them and the
    following subsections will discuss each in detail.
   </para>

   <para>
    All parameter names are case-insensitive. Every parameter takes a
    value of one of the four types: Boolean, integer, floating point,
    and string. Boolean values are <literal>ON</literal>,
    <literal>OFF</literal>, <literal>TRUE</literal>,
    <literal>FALSE</literal>, <literal>YES</literal>,
    <literal>NO</literal>, <literal>1</literal>, <literal>0</literal>
    (case-insensitive) or any non-ambiguous prefix of these.
   </para>

   <para>
    One way to set these options is to edit the file
    <filename>postgresql.conf</filename> in the data directory. (A
    default file is installed there.) An example of what this file might
    look like is:
<programlisting>
# This is a comment
log_connections = yes
syslog = 2
</programlisting>
    As you see, options are one per line. The equal sign between name
    and value is optional. Whitespace is insignificant and blank lines
    are ignored. Hash marks (<quote>#</quote>) introduce comments
    anywhere.
   </para>

   <para>
    <indexterm>
     <primary>SIGHUP</primary>
    </indexterm>
    The configuration file is reread whenever the postmaster receives a
    <systemitem>SIGHUP</> signal (which is most easily sent by means of
    <literal>pg_ctl reload</>). The postmaster also propagates this
    signal to all currently running backend processes so that existing
    sessions also get the new value. Alternatively, you can send the
    signal to a single backend process directly.
   </para>

   <para>
    A second way to set these configuration parameters is to give them
    as a command line option to the postmaster, such as:
<programlisting>
postmaster -c log_connections=yes -c syslog=2
</programlisting>
    which would have the same effect as the previous example.
    Command-line options override any conflicting settings in
    <filename>postgresql.conf</filename>.
   </para>

   <para>
    Occasionally it is also useful to give a command line option to
    one particular backend session only. The environment variable
    <envar>PGOPTIONS</envar> can be used for this purpose on the
    client side:
<programlisting>
env PGOPTIONS='-c geqo=off' psql
</programlisting>
    (This works for any client application, not just
    <application>psql</application>.) Note that this won't work for
    options that are fixed when the server is started, such as the port
    number.
   </para>

   <para>
    Some options can be changed in individual SQL sessions with the
    <command>SET</command> command, for example:
<screen>
=&gt; <userinput>SET ENABLE_SEQSCAN TO OFF;</userinput>
</screen>
    See the SQL command language reference for details on the syntax.
    Furthermore, it is possible to assign a set of option settings to
    a user or a database.  Whenever a session is started, the default
    settings for the user and database involved are loaded.  The
    commands <literal>ALTER DATABASE</literal> and <literal>ALTER
    USER</literal>, respectively, are used to configure these.
   </para>

   <sect2 id="runtime-config-optimizer">
    <title>Planner and Optimizer Tuning</title>

   <para>
    <variablelist>
     <varlistentry>
      <term><varname>CPU_INDEX_TUPLE_COST</varname> (<type>floating point</type>)</term>
      <listitem>
       <para>
        Sets the query optimizer's estimate of the cost of processing
	each index tuple during an index scan. This is measured as a
	fraction of the cost of a sequential page fetch.
       </para>
      </listitem>
     </varlistentry>
    
     <varlistentry>
      <term><varname>CPU_OPERATOR_COST</varname> (<type>floating point</type>)</term>
      <listitem>
       <para>
        Sets the optimizer's estimate of the cost of processing each
	operator in a WHERE clause. This is measured as a fraction of
	the cost of a sequential page fetch.
       </para>
      </listitem>
     </varlistentry>
    
     <varlistentry>
      <term><varname>CPU_TUPLE_COST</varname> (<type>floating point</type>)</term>
      <listitem>
       <para>
        Sets the query optimizer's estimate of the cost of processing
	each tuple during a query. This is measured as a fraction of
	the cost of a sequential page fetch.
       </para>
      </listitem>
     </varlistentry>
    
     <varlistentry>
      <term><varname>EFFECTIVE_CACHE_SIZE</varname> (<type>floating point</type>)</term>
      <listitem>
       <para>
        Sets the optimizer's assumption about the effective size of the
        disk cache (that is, the portion of the kernel's disk cache that
        will be used for <productname>PostgreSQL</productname> data
        files). This is measured in disk pages, which are normally 8 kB
        each.
       </para>
      </listitem>
     </varlistentry>

     <varlistentry>
      <term><varname>ENABLE_HASHJOIN</varname> (<type>boolean</type>)</term>
      <listitem>
       <para>
        Enables or disables the query planner's use of hash-join plan
        types. The default is on. This is used for debugging the
        query planner.
       </para>
      </listitem>
     </varlistentry>

     <varlistentry>
      <indexterm>
       <primary>index scan</primary>
      </indexterm>

      <term><varname>ENABLE_INDEXSCAN</varname> (<type>boolean</type>)</term>
      <listitem>
       <para>
        Enables or disables the query planner's use of index-scan plan
        types. The default is on. This is used to debugging the
        query planner.
       </para>
      </listitem>
     </varlistentry>

     <varlistentry>
      <term><varname>ENABLE_MERGEJOIN</varname> (<type>boolean</type>)</term>
      <listitem>
       <para>
        Enables or disables the query planner's use of merge-join plan
        types. The default is on. This is used for debugging the
        query planner.
       </para>
      </listitem>
     </varlistentry>

     <varlistentry>
      <term><varname>ENABLE_NESTLOOP</varname> (<type>boolean</type>)</term>
      <listitem>
       <para>
        Enables or disables the query planner's use of nested-loop join
        plans. It's not possible to suppress nested-loop joins entirely,
        but turning this variable off discourages the planner from using
        one if there are other methods available. The default is
        on. This is used for debugging the query planner.
       </para>
      </listitem>
     </varlistentry>

     <varlistentry>
      <indexterm>
       <primary>sequential scan</primary>
      </indexterm>

      <term><varname>ENABLE_SEQSCAN</varname> (<type>boolean</type>)</term>
      <listitem>
       <para>
        Enables or disables the query planner's use of sequential scan
        plan types. It's not possible to suppress sequential scans
        entirely, but turning this variable off discourages the planner
        from using one if there are other methods available. The
        default is on. This is used for debugging the query planner.
       </para>
      </listitem>
     </varlistentry>

     <varlistentry>
      <term><varname>ENABLE_SORT</varname> (<type>boolean</type>)</term>
      <listitem>
       <para>
        Enables or disables the query planner's use of explicit sort
	steps. It's not possible to suppress explicit sorts entirely,
	but turning this variable off discourages the planner from
	using one if there are other methods available. The default
	is on. This is used for debugging the query planner.
       </para>
      </listitem>
     </varlistentry>

     <varlistentry>
      <term><varname>ENABLE_TIDSCAN</varname> (<type>boolean</type>)</term>
      <listitem>
       <para>
        Enables or disables the query planner's use of <acronym>TID</> scan plan
        types. The default is on. This is used for debugging the
        query planner.
       </para>
      </listitem>
     </varlistentry>

     <varlistentry>
      <indexterm>
       <primary>genetic query optimization</primary>
      </indexterm>
      <indexterm>
       <primary>GEQO</primary>
       <see>genetic query optimization</see>
      </indexterm>

      <term><varname>GEQO</varname> (<type>boolean</type>)</term>
      <listitem>
       <para>
        Enables or disables genetic query optimization, which is an
        algorithm that attempts to do query planning without exhaustive
        searching. This is on by default. See also the various other
        <varname>GEQO_</varname> settings.
       </para>
      </listitem>
     </varlistentry>

     <varlistentry>
      <term><varname>GEQO_EFFORT</varname> (<type>integer</type>)</term>
      <term><varname>GEQO_GENERATIONS</varname> (<type>integer</type>)</term>
      <term><varname>GEQO_POOL_SIZE</varname> (<type>integer</type>)</term>
      <term><varname>GEQO_RANDOM_SEED</varname> (<type>integer</type>)</term>
      <term><varname>GEQO_SELECTION_BIAS</varname> (<type>floating point</type>)</term>
      <listitem>
       <para>
        Various tuning parameters for the genetic query optimization
        algorithm: The pool size is the number of individuals in one
        population. Valid values are between 128 and 1024. If it is set
        to 0 (the default) a pool size of 2^(QS+1), where QS is the
        number of FROM items in the query, is taken. The effort is used
        to calculate a default for generations. Valid values are between
        1 and 80, 40 being the default. Generations specifies the number
        of iterations in the algorithm. The number must be a positive
        integer. If 0 is specified then <literal>Effort *
        Log2(PoolSize)</literal> is used. The run time of the algorithm
        is roughly proportional to the sum of pool size and generations.
        The selection bias is the selective pressure within the
        population. Values can be from 1.50 to 2.00; the latter is the
        default. The random seed can be set to get reproducible results
        from the algorithm. If it is set to -1 then the algorithm
        behaves non-deterministically.
       </para>
      </listitem>
     </varlistentry>

     <varlistentry>
      <term><varname>GEQO_THRESHOLD</varname> (<type>integer</type>)</term>
      <listitem>
       <para>
        Use genetic query optimization to plan queries with at least
        this many <literal>FROM</> items involved. (Note that a
        <literal>JOIN</> construct counts as only one <literal>FROM</>
        item.) The default is 11. For simpler queries it is usually best
        to use the deterministic, exhaustive planner. This parameter
        also controls how hard the optimizer will try to merge subquery
        <literal>FROM</literal> clauses into the upper query.
       </para>
      </listitem>
     </varlistentry>

     <varlistentry>
      <term><varname>KSQO</varname> (<type>boolean</type>)</term>
      <listitem>
       <para>
        The <firstterm>Key Set Query Optimizer</firstterm>
        (<acronym>KSQO</acronym>) causes the query planner to convert
        queries whose <literal>WHERE</> clause contains many OR'ed AND
        clauses (such as <literal>WHERE (a=1 AND b=2) OR (a=2 AND b=3)
        ...</literal>) into a union query. This method can be faster
        than the default implementation, but it doesn't necessarily give
        exactly the same results, since <literal>UNION</> implicitly
        adds a <literal>SELECT DISTINCT</> clause to eliminate identical
        output rows. <acronym>KSQO</acronym> is commonly used when
        working with products like <productname>Microsoft
        Access</productname>, which tend to generate queries of this
        form.
       </para>

       <para>
        The <acronym>KSQO</acronym> algorithm used to be absolutely
        essential for queries with many OR'ed AND clauses, but in
        <productname>PostgreSQL</productname> 7.0 and later the standard
        planner handles these queries fairly successfully; hence the
        default is off.
       </para>
      </listitem>
     </varlistentry>

     <varlistentry>
      <term><varname>RANDOM_PAGE_COST</varname> (<type>floating point</type>)</term>
      <listitem>
       <para>
        Sets the query optimizer's estimate of the cost of a
        nonsequentially fetched disk page. This is measured as a
        multiple of the cost of a sequential page fetch.
       </para>
      </listitem>
     </varlistentry>
    </variablelist>
   </para>

   <note>
    <para>
     Unfortunately, there is no well-defined method for determining
     ideal values for the family of <quote>COST</quote> variables that
     were just described. You are encouraged to experiment and share
     your findings.
    </para>
   </note>

   </sect2>

   <sect2 id="logging">
    <title>Logging and Debugging</title>

   <para>
    <variablelist>
     <varlistentry>
      <term><varname>SERVER_MIN_MESSAGES</varname> (<type>string</type>)</term>
      <listitem>
       <para>
        This controls how much detail is written to the server logs. The
        default is <literal>NOTICE</>. Valid values are <literal>DEBUG5</>,
        <literal>DEBUG4</>, <literal>DEBUG3</>, <literal>DEBUG2</>,
        <literal>DEBUG1</>, <literal>INFO</>, <literal>NOTICE</>,
        <literal>WARNING</>, <literal>ERROR</>, <literal>LOG</>, 
	<literal>FATAL</>, and <literal>PANIC</>. Later values send less 
	detail to the logs. <literal>LOG</> has a different precedence 
	here than in <literal>CLIENT_MIN_MESSAGES</>.
       </para>
      </listitem>
     </varlistentry>

     <varlistentry>
      <term><varname>CLIENT_MIN_MESSAGES</varname> (<type>string</type>)</term>
      <listitem>
       <para>
        This controls how much detail is written to the client. The
        default is <literal>NOTICE</>. Valid values are
        <literal>DEBUG5</>, <literal>DEBUG4</>, <literal>DEBUG3</>,
        <literal>DEBUG2</>, <literal>DEBUG1</>, <literal>LOG</>,
        <literal>NOTICE</>, <literal>WARNING</>, and <literal>ERROR</>. 
	Later values send less information to the user. <literal>LOG</> 
	has a different precedence here than in 
	<literal>SERVER_MIN_MESSAGES</>.
       </para>
      </listitem>
     </varlistentry>

     <varlistentry>
      <term><varname>DEBUG_ASSERTIONS</varname> (<type>boolean</type>)</term>
      <listitem>
       <para>
        Turns on various assertion checks. This is a debugging aid. If
        you are experiencing strange problems or crashes you might want
        to turn this on, as it might expose programming mistakes. To use
        this option, the macro <literal>USE_ASSERT_CHECKING</literal>
        must be defined when <productname>PostgreSQL</productname> is
        built (see the configure option
        <literal>--enable-cassert</literal>). Note that
        <literal>DEBUG_ASSERTIONS</literal> defaults to on if
        <productname>PostgreSQL</productname> has been built this way.
       </para>
      </listitem>
     </varlistentry>

     <varlistentry>
      <term><varname>DEBUG_PRINT_QUERY</varname> (<type>boolean</type>)</term>
      <term><varname>DEBUG_PRINT_PARSE</varname> (<type>boolean</type>)</term>
      <term><varname>DEBUG_PRINT_REWRITTEN</varname> (<type>boolean</type>)</term>
      <term><varname>DEBUG_PRINT_PLAN</varname> (<type>boolean</type>)</term>
      <term><varname>DEBUG_PRETTY_PRINT</varname> (<type>boolean</type>)</term>
      <listitem>
       <para>
        These flags enable various debugging output to be sent to the
	server log.  For each executed query, prints either the query text,
	the resulting parse tree, the query rewriter output, or the execution
	plan. <option>DEBUG_PRETTY_PRINT</option> indents these displays
	to produce a more readable but much longer output format.
       </para>
      </listitem>
     </varlistentry>

     <varlistentry>
      <term><varname>EXPLAIN_PRETTY_PRINT</varname> (<type>boolean</type>)</term>
      <listitem>
       <para>
        Determines whether <command>EXPLAIN VERBOSE</> uses the indented
	or non-indented format for displaying detailed querytree dumps.
       </para>
      </listitem>
     </varlistentry>

     <varlistentry>
      <term><varname>HOSTNAME_LOOKUP</varname> (<type>boolean</type>)</term>
      <listitem>
       <para>
        By default, connection logs only show the IP address of the
        connecting host. If you want it to show the host name you can
        turn this on, but depending on your host name resolution setup
        it might impose a non-negligible performance penalty. This
        option can only be set at server start.
       </para>
      </listitem>
     </varlistentry>

     <varlistentry>
      <term><varname>LOG_CONNECTIONS</varname> (<type>boolean</type>)</term>
      <listitem>
       <para>
        This outputs a line to the server logs detailing each successful
        connection. This is off by default, although it is probably very
        useful. This option can only be set at server start or in the
        <filename>postgresql.conf</filename> configuration file.
       </para>
      </listitem>
     </varlistentry>

     <varlistentry>
      <term><varname>LOG_PID</varname> (<type>boolean</type>)</term>
      <listitem>
       <para>
        Prefixes each server log message with the process ID of the
        backend process. This is useful to sort out which messages
        pertain to which connection. The default is off.
       </para>
      </listitem>
     </varlistentry>

     <varlistentry>
      <term><varname>LOG_TIMESTAMP</varname> (<type>boolean</type>)</term>
      <listitem>
       <para>
        Prefixes each server log message with a time stamp. The default
        is off.
       </para>
      </listitem>
     </varlistentry>

     <varlistentry>
      <term><varname>SHOW_QUERY_STATS</varname> (<type>boolean</type>)</term>
      <term><varname>SHOW_PARSER_STATS</varname> (<type>boolean</type>)</term>
      <term><varname>SHOW_PLANNER_STATS</varname> (<type>boolean</type>)</term>
      <term><varname>SHOW_EXECUTOR_STATS</varname> (<type>boolean</type>)</term>
      <listitem>
       <para>
        For each query, write performance statistics of the respective
        module to the server log. This is a crude profiling
        instrument.
       </para>
      </listitem>
     </varlistentry>

     <varlistentry>
      <term><varname>SHOW_SOURCE_PORT</varname> (<type>boolean</type>)</term>
      <listitem>
       <para>
        Shows the outgoing port number of the connecting host in the
        connection log messages. You could trace back the port number
        to find out what user initiated the connection. Other than
        that, it's pretty useless and therefore off by default. This
        option can only be set at server start.
       </para>
      </listitem>
     </varlistentry>

     <varlistentry>
      <term><varname>STATS_COMMAND_STRING</varname> (<type>boolean</type>)</term>
      <term><varname>STATS_BLOCK_LEVEL</varname> (<type>boolean</type>)</term>
      <term><varname>STATS_ROW_LEVEL</varname> (<type>boolean</type>)</term>
      <listitem>
       <para>
        These flags determine what information backends send to the statistics
	collector process: current commands, block-level activity statistics,
	or row-level activity statistics.  All default to off.  Enabling
	statistics collection costs a small amount of time per query, but
	is invaluable for debugging and performance tuning.
       </para>
      </listitem>
     </varlistentry>

     <varlistentry>
      <term><varname>STATS_RESET_ON_SERVER_START</varname> (<type>boolean</type>)</term>
      <listitem>
       <para>
        If on, collected statistics are zeroed out whenever the server
        is restarted. If off, statistics are accumulated across server
        restarts. The default is on. This option can only be set at
        server start.
       </para>
      </listitem>
     </varlistentry>

     <varlistentry>
      <term><varname>STATS_START_COLLECTOR</varname> (<type>boolean</type>)</term>
      <listitem>
       <para>
        Controls whether the server should start the statistics-collection
	subprocess.  This is on by default, but may be turned off if you
	know you have no interest in collecting statistics.  This option
	can only be set at server start.
       </para>
      </listitem>
     </varlistentry>

     <varlistentry>
      <term><varname>SYSLOG</varname> (<type>integer</type>)</term>
      <listitem>
       <para>
        <productname>PostgreSQL</productname> allows the use of
        <systemitem>syslog</systemitem> for logging. If this option is
        set to 1, messages go both to <systemitem>syslog</> and the
        standard output. A setting of 2 sends output only to
        <systemitem>syslog</>. (Some messages will still go to the
        standard output/error.) The default is 0, which means
        <systemitem>syslog</> is off. This option must be set at server
        start.
       </para>
       <para>
        To use <systemitem>syslog</>, the build of
        <productname>PostgreSQL</productname> must be configured with
        the <option>--enable-syslog</option> option.
       </para>
      </listitem>
     </varlistentry>

     <varlistentry>
      <term><varname>SYSLOG_FACILITY</varname> (<type>string</type>)</term>
       <listitem>
        <para>
          This option determines the <application>syslog</application>
          <quote>facility</quote> to be used when
          <application>syslog</application> is enabled. You may choose
          from LOCAL0, LOCAL1, LOCAL2, LOCAL3, LOCAL4, LOCAL5, LOCAL6,
          LOCAL7; the default is LOCAL0. See also the documentation of
          your system's <application>syslog</application>.
        </para>
       </listitem>
     </varlistentry>
     
     <varlistentry>
      <term><varname>SYSLOG_IDENT</varname> (<type>string</type>)</term>
       <listitem>
        <para>
         If logging to <application>syslog</> is enabled, this option
         determines the program name used to identify
         <productname>PostgreSQL</productname> messages in
         <application>syslog</application> log messages. The default is
         <literal>postgres</literal>.
        </para>
       </listitem>
      </varlistentry>

     <varlistentry>
      <term><varname>TRACE_NOTIFY</varname> (<type>boolean</type>)</term>
      <listitem>
       <para>
        Generates a great amount of debugging output for the
        <command>LISTEN</command> and <command>NOTIFY</command>
        commands.
       </para>
      </listitem>
     </varlistentry>
    </variablelist>
   </para>
   </sect2>

   <sect2 id="runtime-config-general">
    <title>General operation</title>

   <para>
    <variablelist>
     <varlistentry>
      <term><varname>AUSTRALIAN_TIMEZONES</varname> (<type>bool</type>)</term>
      <indexterm><primary>Australian time zones</></>
      <listitem>
       <para>
        If set to true, <literal>CST</literal>, <literal>EST</literal>,
        and <literal>SAT</literal> are interpreted as Australian
        time zones rather than as North American Central/Eastern
        time zones and Saturday. The default is false.
       </para>
      </listitem>
     </varlistentry>

     <varlistentry>
      <term><varname>AUTHENTICATION_TIMEOUT</varname> (<type>integer</type>)</term>
      <indexterm><primary>timeout</><secondary>authentication</></indexterm>
      <listitem>
       <para>
        Maximum time to complete client authentication, in seconds. If a
        would-be client has not completed the authentication protocol in
        this much time, the server breaks the connection. This prevents
        hung clients from occupying a connection indefinitely. This
        option can only be set at server start or in the
        <filename>postgresql.conf</filename> file.
       </para>
      </listitem>
     </varlistentry>

     <varlistentry>
      <indexterm>
       <primary>deadlock</primary>
       <secondary>timeout</secondary>
      </indexterm>
      <indexterm>
       <primary>timeout</primary>
       <secondary>deadlock</secondary>
      </indexterm>

      <term><varname>DEADLOCK_TIMEOUT</varname> (<type>integer</type>)</term>
      <listitem>
       <para>
        This is the amount of time, in milliseconds, to wait on a lock
        before checking to see if there is a deadlock condition. The
        check for deadlock is relatively slow, so the server doesn't run
        it every time it waits for a lock. We (optimistically?) assume
        that deadlocks are not common in production applications and
        just wait on the lock for a while before starting check for a
        deadlock. Increasing this value reduces the amount of time
        wasted in needless deadlock checks, but slows down reporting of
        real deadlock errors. The default is 1000 (i.e., one second),
        which is probably about the smallest value you would want in
        practice. On a heavily loaded server you might want to raise it.
        Ideally the setting should exceed your typical transaction time,
        so as to improve the odds that the lock will be released before
        the waiter decides to check for deadlock. This option can only
        be set at server start.
       </para>
      </listitem>
     </varlistentry>

     <varlistentry>
      <indexterm>
       <primary>transaction isolation level</primary>
      </indexterm>

      <term><varname>DEFAULT_TRANSACTION_ISOLATION</varname> (<type>string</type>)</term>
      <listitem>
       <para>
        Each SQL transaction has an isolation level, which can be either
        <quote>read committed</quote> or <quote>serializable</quote>.
        This parameter controls the default isolation level of each new
        transaction. The default is <quote>read committed</quote>.
       </para>

       <para>
        Consult the <citetitle>PostgreSQL User's Guide</citetitle> and
        the command <command>SET TRANSACTION</command> for more
        information.
       </para>
      </listitem>
     </varlistentry>

     <varlistentry>
      <term><varname>DYNAMIC_LIBRARY_PATH</varname> (<type>string</type>)</term>
      <indexterm><primary>dynamic_library_path</></>
      <indexterm><primary>dynamic loading</></>
      <listitem>
       <para>
        If a dynamically loadable module needs to be opened and the
        specified name does not have a directory component (i.e. the
        name does not contain a slash), the system will search this
        path for the specified file.  (The name that is used is the
        name specified in the <command>CREATE FUNCTION</command> or
        <command>LOAD</command> command.)
       </para>

       <para>
        The value for dynamic_library_path has to be a colon-separated
        list of absolute directory names. If a directory name starts
        with the special value <literal>$libdir</literal>, the
        compiled-in <productname>PostgreSQL</productname> package
        library directory is substituted. This where the modules
        provided by the <productname>PostgreSQL</productname>
        distribution are installed. (Use <literal>pg_config
        --pkglibdir</literal> to print the name of this directory.) For
        example:
        <informalexample>
<programlisting>
dynamic_library_path = '/usr/local/lib/postgresql:/home/my_project/lib:$libdir'
</programlisting>
        </informalexample>
       </para>

       <para>
        The default value for this parameter is
        <literal>'$libdir'</literal>. If the value is set to an empty
        string, the automatic path search is turned off.
       </para>

       <para>
        This parameter can be changed at run time by superusers, but a
        setting done that way will only persist until the end of the
        client connection, so this method should be reserved for
        development purposes. The recommended way to set this parameter
        is in the <filename>postgresql.conf</filename> configuration
        file.
       </para>
      </listitem>
     </varlistentry>

     <varlistentry>
      <term><varname>SEARCH_PATH</varname> (<type>string</type>)</term>
      <indexterm><primary>search_path</></>
      <indexterm><primary>namespaces</></>
      <listitem>
       <para>
        This variable specifies the order in which namespaces are searched
	when an object (table, datatype, function, etc) is referenced by a
	simple name with no schema component.  When there are objects of
	identical names in different namespaces, the one found first
	in the search path is used.  An object that is not in any of the
	namespaces in the search path can only be referenced by specifying
	its containing namespace with a qualified (dotted) name.
       </para>

       <para>
        The value for search_path has to be a comma-separated
        list of namespace (schema) names.  If one of the list items is
        the special value <literal>$user</literal>, then the namespace
	having the same name as the SESSION_USER is substituted, if there
	is such a namespace.  (If not, <literal>$user</literal> is ignored.)
       </para>

       <para>
        The system catalog namespace, <literal>pg_catalog</>, is always
	searched, whether it is mentioned in the path or not.  If it is
	mentioned in the path then it will be searched in the specified
	order.  If <literal>pg_catalog</> is not in the path then it will
	be searched <emphasis>before</> searching any of the path items.
	It should also be noted that the temporary-table namespace,
	<literal>pg_temp_nnn</>, is implicitly searched before any of
	these.
       </para>

       <para>
        When objects are created without specifying a particular target
	namespace, they will be placed in the first namespace listed
	in the search path.  An error is reported if the search path is
	empty.
       </para>

       <para>
        The default value for this parameter is
        <literal>'$user, public'</literal> (where the second part will be
	ignored if there is no namespace named <literal>public</>).
	This supports shared use of a database (where no users
	have private namespaces, and all share use of <literal>public</>),
	private per-user namespaces, and combinations of these.  Other
	effects can be obtained by altering the default search path
	setting, either globally or per-user.
       </para>

       <para>
        By default, a newly created database will contain a world-writable
	namespace named <literal>public</>, but no private namespaces.
	The administrator may choose to restrict permissions on
	<literal>public</> or even remove it, if that suits his purposes.
       </para>
      </listitem>
     </varlistentry>

     <varlistentry>
      <indexterm>
       <primary>fsync</primary>
      </indexterm>

      <term><varname>FSYNC</varname> (<type>boolean</type>)</term>
      <listitem>
       <para>
        If this option is on, the <productname>PostgreSQL</> backend
        will use the <function>fsync()</> system call in several places
        to make sure that updates are physically written to disk. This
        insures that a database installation will recover to a
        consistent state after an operating system or hardware crash.
        (Crashes of the database server itself are <emphasis>not</>
        related to this.)
       </para>

       <para>
        However, this operation does slow down
        <productname>PostgreSQL</> because at transaction commit it has
        wait for the operating system to flush the write-ahead log.
        Without <function>fsync</>, the operating system is allowed to
        do its best in buffering, sorting, and delaying writes, which
        can considerably increase performance. However, if the system
        crashes, the results of the last few committed transactions may
        be lost in part or whole. In the worst case, unrecoverable data
        corruption may occur.
       </para>

       <para>
        For the above reasons, some administrators always leave it off,
        some turn it off only for bulk loads, where there is a clear
        restart point if something goes wrong, and some leave it on just
        to be on the safe side. Because it is always safe, the default
        is on. If you trust your operating system, your hardware, and
        your utility company (or better your UPS), you might want to
        disable <varname>fsync</varname>.
       </para>

       <para>
        It should be noted that the performance penalty of doing
        <function>fsync</>s is considerably less in
        <productname>PostgreSQL</> version 7.1 and later. If you
        previously suppressed <function>fsync</>s for performance
        reasons, you may wish to reconsider your choice.
       </para>

       <para>
	This option can only be set at server start or in the
	<filename>postgresql.conf</filename> file.
       </para>
      </listitem>
     </varlistentry>

     <varlistentry>
      <term><varname>KRB_SERVER_KEYFILE</varname> (<type>string</type>)</term>
      <listitem>
       <para>
        Sets the location of the Kerberos server key file. See
        <xref linkend="kerberos-auth"> for details.
       </para>
      </listitem>
     </varlistentry>

     <varlistentry>
      <term><varname>LC_MESSAGES</varname> (<type>string</type>)</term>
      <listitem>
       <para>
        Sets the language in which messages are displayed.  Acceptable
        values are system-dependent; see <xref linkend="locale"> for
        more information.  If this variable is set to the empty string
        (which is the default) then the value is inherited from the
        execution environment of the server in a system-dependent way.
       </para>

       <para>
        On some systems, this locale category does not exist.  Setting
        this variable will still work, but there will be no effect.
        Also, there is a chance that no translated messages for the
        desired language exist.  In that case you will continue to see
        the English messages.
       </para>
      </listitem>
     </varlistentry>

     <varlistentry>
      <term><varname>LC_MONETARY</varname> (<type>string</type>)</term>
      <listitem>
       <para>
        Sets the locale to use for formatting monetary amounts.
        Acceptable values are system-dependent; see <xref
        linkend="locale"> for more information.  If this variable is
        set to the empty string (which is the default) then the value
        is inherited from the execution environment of the server in a
        system-dependent way.
       </para>
      </listitem>
     </varlistentry>

     <varlistentry>
      <term><varname>LC_NUMERIC</varname> (<type>string</type>)</term>
      <listitem>
       <para>
        Sets the locale to use for formatting numbers, for example
        with the <function>to_char()</function> family of
        functions. Acceptable values are system-dependent; see <xref
        linkend="locale"> for more information.  If this variable is
        set to the empty string (which is the default) then the value
        is inherited from the execution environment of the server in a
        system-dependent way.
       </para>
      </listitem>
     </varlistentry>

     <varlistentry>
      <term><varname>LC_TIME</varname> (<type>string</type>)</term>
      <listitem>
       <para>
        Sets the locale to use for formatting date and time values,
        for example with the <function>to_char()</function> family of
        functions. Acceptable values are system-dependent; see <xref
        linkend="locale"> for more information.  If this variable is
        set to the empty string (which is the default) then the value
        is inherited from the execution environment of the server in a
        system-dependent way.
       </para>
      </listitem>
     </varlistentry>

     <varlistentry>
      <term><varname>MAX_CONNECTIONS</varname> (<type>integer</type>)</term>
      <listitem>
       <para>
        Determines the maximum number of concurrent connections to the
        database server. The default is 32 (unless altered while
        building the server). This parameter can only be set at server
        start.
       </para>
      </listitem>
     </varlistentry>

     <varlistentry>
      <term><varname>MAX_EXPR_DEPTH</varname> (<type>integer</type>)</term>
      <listitem>
       <para>
        Sets the maximum expression nesting depth of the parser. The
        default value is high enough for any normal query, but you can
        raise it if needed. (But if you raise it too high, you run
        the risk of backend crashes due to stack overflow.)
       </para>
      </listitem>
     </varlistentry>

     <varlistentry>
      <term><varname>MAX_FILES_PER_PROCESS</varname> (<type>integer</type>)</term>
      <listitem>
       <para>
        Sets the maximum number of simultaneously open files in each
        server subprocess. The default is 1000. The limit actually used
        by the code is the smaller of this setting and the result of
        <literal>sysconf(_SC_OPEN_MAX)</literal>. Therefore, on systems
        where <function>sysconf</> returns a reasonable limit, you don't
        need to worry about this setting. But on some platforms
        (notably, most BSD systems), <function>sysconf</> returns a
        value that is much larger than the system can really support
        when a large number of processes all try to open that many
        files. If you find yourself seeing <quote>Too many open files</>
        failures, try reducing this setting. This option can only be set
        at server start or in the <filename>postgresql.conf</filename>
        configuration file; if changed in the configuration file, it
        only affects subsequently-started server subprocesses.
       </para>
      </listitem>
     </varlistentry>

     <varlistentry>
      <term><varname>MAX_FSM_RELATIONS</varname> (<type>integer</type>)</term>
      <listitem>
       <para>
        Sets the maximum number of relations (tables) for which free
        space will be tracked in the shared free-space map. The default
        is 100. This option can only be set at server start.
       </para>
      </listitem>
     </varlistentry>

     <varlistentry>
      <term><varname>MAX_FSM_PAGES</varname> (<type>integer</type>)</term>
      <listitem>
       <para>
        Sets the maximum number of disk pages for which free space will
        be tracked in the shared free-space map. The default is 10000.
        This option can only be set at server start.
       </para>
      </listitem>
     </varlistentry>

     <varlistentry>
      <term><varname>MAX_LOCKS_PER_TRANSACTION</varname> (<type>integer</type>)</term>
      <listitem>
       <para>
        The shared lock table is sized on the assumption that at most
        <varname>max_locks_per_transaction</> *
        <varname>max_connections</varname> distinct objects will need to
        be locked at any one time. The default, 64, which has historically
        proven sufficient, but you might need to raise this value if you
        have clients that touch many different tables in a single
        transaction. This option can only be set at server start.
       </para>
      </listitem>
     </varlistentry>

     <varlistentry>
      <term><varname>PASSWORD_ENCRYPTION</varname> (<type>boolean</type>)</term>
      <listitem>
       <para>
        When a password is specified in <command>CREATE USER</> or
        <command>ALTER USER</> without writing either ENCRYPTED or
        UNENCRYPTED, this flag determines whether the password is to be
        encrypted. The default is off (do not encrypt the password), but
        this choice may change in a future release.
       </para>
      </listitem>
     </varlistentry>

     <varlistentry>
      <term><varname>PORT</varname> (<type>integer</type>)</term>
      <indexterm><primary>port</></>
      <listitem>
       <para>
        The TCP port the server listens on; 5432 by default. This
        option can only be set at server start.
       </para>
      </listitem>
     </varlistentry>

     <varlistentry>
      <term><varname>SHARED_BUFFERS</varname> (<type>integer</type>)</term>
      <listitem>
       <para>
        Sets the number of shared memory buffers used by the database
        server. The default is 64. Each buffer is typically 8192 bytes.
        This option can only be set at server start.
       </para>
      </listitem>
     </varlistentry>

     <varlistentry>
      <term><varname>SILENT_MODE</varname> (<type>bool</type>)</term>
      <listitem>
       <para>
        Runs postmaster silently. If this option is set, the postmaster
        will automatically run in background and any controlling ttys
        are disassociated, thus no messages are written to standard
        output or standard error (same effect as postmaster's -S
        option). Unless some logging system such as
        <application>syslog</> is enabled, using this option is
        discouraged since it makes it impossible to see error messages.
       </para>
      </listitem>
     </varlistentry>

     <varlistentry>
      <term><varname>SORT_MEM</varname> (<type>integer</type>)</term>
      <listitem>
       <para>
	Specifies the amount of memory to be used by internal sorts and
	hashes before switching to temporary disk files. The value is
	specified in kilobytes, and defaults to 512 kilobytes. Note that
	for a complex query, several sorts and/or hashes might be
	running in parallel, and each one will be allowed to use as much
	memory as this value specifies before it starts to put data into
	temporary files. Also, each running backend could be doing one
	or more sorts simultaneously, so the total memory used could be
	many times the value of <varname>SORT_MEM</varname>.
       </para>
      </listitem>
     </varlistentry>

     <varlistentry>
      <term><varname>SQL_INHERITANCE</varname> (<type>bool</type>)</term>
      <indexterm><primary>inheritance</></>
      <listitem>
       <para>
        This controls the inheritance semantics, in particular whether
        subtables are included by various commands by default. They were
        not included in versions prior to 7.1. If you need the old
        behavior you can set this variable to off, but in the long run
        you are encouraged to change your applications to use the
        <literal>ONLY</literal> keyword to exclude subtables. See the
        SQL language reference and the <citetitle>User's
        Guide</citetitle> for more information about inheritance.
       </para>
      </listitem>
     </varlistentry>

     <varlistentry>
      <indexterm>
       <primary>SSL</primary>
      </indexterm>

      <term><varname>SSL</varname> (<type>boolean</type>)</term>
      <listitem>
       <para>
        Enables <acronym>SSL</> connections. Please read
        <xref linkend="ssl-tcp"> before using this. The default
        is off.
       </para>
      </listitem>
     </varlistentry>

     <varlistentry>
      <term><varname>TCPIP_SOCKET</varname> (<type>boolean</type>)</term>
      <listitem>
       <para>
        If this is true, then the server will accept TCP/IP connections.
        Otherwise only local Unix domain socket connections are
        accepted. It is off by default. This option can only be set at
        server start.
       </para>
      </listitem>
     </varlistentry>

     <varlistentry>
      <term><varname>TRANSFORM_NULL_EQUALS</varname> (<type>boolean</type>)</term>
      <indexterm><primary>IS NULL</></>
      <listitem>
       <para>
        When turned on, expressions of the form
        <literal><replaceable>expr</> = NULL</literal> (or <literal>NULL
        = <replaceable>expr</></literal>) are treated as
        <literal><replaceable>expr</> IS NULL</literal>, that is, they
        return true if <replaceable>expr</> evaluates to the NULL value,
        and false otherwise. The correct behavior of
        <literal><replaceable>expr</> = NULL</literal> is to always
        return NULL (unknown). Therefore this option defaults to off.
       </para>

       <para>
        However, filtered forms in <productname>Microsoft
        Access</productname> generate queries that appear to use
        <literal><replaceable>expr</> = NULL</literal> to test for
        NULLs, so if you use that interface to access the database you
        might want to turn this option on.  Since expressions of the
        form <literal><replaceable>expr</> = NULL</literal> always
        return NULL (using the correct interpretation) they are not
        very useful and do not appear often in normal applications, so
        this option does little harm in practice.  But new users are
        frequently confused about the semantics of expressions
        involving NULL, so this option is not on by default.
       </para>

       <para>
        Note that this option only affects the literal <literal>=</>
        operator, not other comparison operators or other expressions
        that are computationally equivalent to some expression
        involving the equals operator (such as <literal>IN</literal>).
        Thus, this option is not a general fix for bad programming.
       </para>

       <para>
        Refer to the <citetitle>User's Guide</citetitle> for related
        information.
       </para>
      </listitem>
     </varlistentry>

     <varlistentry>
      <term><varname>UNIX_SOCKET_DIRECTORY</varname> (<type>string</type>)</term>
      <listitem>
       <para>
	Specifies the directory of the Unix-domain socket on which the
	<application>postmaster</application> is to listen for
	connections from client applications.  The default is normally
	<filename>/tmp</filename>, but can be changed at build time.
       </para>
      </listitem>
     </varlistentry>

     <varlistentry>
      <term><varname>UNIX_SOCKET_GROUP</varname> (<type>string</type>)</term>
      <listitem>
       <para>
        Sets the group owner of the Unix domain socket.  (The owning
        user of the socket is always the user that starts the
        postmaster.)  In combination with the option
        <option>UNIX_SOCKET_PERMISSIONS</option> this can be used as
        an additional access control mechanism for this socket type.
        By default this is the empty string, which uses the default
        group for the current user.  This option can only be set at
        server start.
       </para>
      </listitem>
     </varlistentry>

     <varlistentry>
      <term><varname>UNIX_SOCKET_PERMISSIONS</varname> (<type>integer</type>)</term>
      <listitem>
       <para>
        Sets the access permissions of the Unix domain socket.  Unix
        domain sockets use the usual Unix file system permission set.
        The option value is expected to be an numeric mode
        specification in the form accepted by the
        <function>chmod</function> and <function>umask</function>
        system calls.  (To use the customary octal format the number
        must start with a <literal>0</literal> (zero).)
       </para>

       <para>
        The default permissions are <literal>0777</literal>, meaning
        anyone can connect. Reasonable alternatives are
        <literal>0770</literal> (only user and group, see also under
        <option>UNIX_SOCKET_GROUP</option>) and <literal>0700</literal>
        (only user). (Note that actually for a Unix socket, only write
        permission matters and there is no point in setting or revoking
        read or execute permissions.)
       </para>

       <para>
        This access control mechanism is independent of the one
        described in <xref linkend="client-authentication">.
       </para>

       <para>
        This option can only be set at server start.
       </para>
      </listitem>
     </varlistentry>

     <varlistentry>
      <term><varname>VACUUM_MEM</varname> (<type>integer</type>)</term>
      <listitem>
       <para>
	Specifies the maximum amount of memory to be used by
	<command>VACUUM</command> to keep track of to-be-reclaimed
	tuples. The value is specified in kilobytes, and defaults to
	8192 kilobytes. Larger settings may improve the speed of
	vacuuming large tables that have many deleted tuples.
       </para>
      </listitem>
     </varlistentry>

     <varlistentry>
      <term><varname>VIRTUAL_HOST</varname> (<type>string</type>)</term>
      <listitem>
       <para>
	Specifies the TCP/IP host name or address on which the
	<application>postmaster</application> is to listen for
	connections from client applications. Defaults to listening on
	all configured addresses (including <systemitem
	class="systemname">localhost</>).
       </para>
      </listitem>
     </varlistentry>

    </variablelist>
   </para>
   </sect2>

   <sect2 id="runtime-config-wal">
    <title>WAL</title>

   <para>
    See also <xref linkend="wal-configuration"> for details on WAL
    tuning.

    <variablelist>
     <varlistentry>
      <term><varname>CHECKPOINT_SEGMENTS</varname> (<type>integer</type>)</term>
      <listitem>
       <para>
        Maximum distance between automatic WAL checkpoints, in log file
	segments (each segment is normally 16 megabytes).
	This option can only be set at server start or in the
	<filename>postgresql.conf</filename> file.
       </para>
      </listitem>
     </varlistentry>

     <varlistentry>
      <term><varname>CHECKPOINT_TIMEOUT</varname> (<type>integer</type>)</term>
      <listitem>
       <para>
        Maximum time between automatic WAL checkpoints, in seconds.
	This option can only be set at server start or in the
	<filename>postgresql.conf</filename> file.
       </para>
      </listitem>
     </varlistentry>

     <varlistentry>
      <term><varname>COMMIT_DELAY</varname> (<type>integer</type>)</term>
      <listitem>
       <para>
        Time delay between writing a commit record to the WAL buffer and
        flushing the buffer out to disk, in microseconds. A nonzero
        delay allows multiple transactions to be committed with only one
        <function>fsync</function> system call, if system load is high
        enough additional transactions may become ready to commit within
        the given interval. But the delay is just wasted if no other
        transactions become ready to commit. Therefore, the delay is
        only performed if at least COMMIT_SIBLINGS other transactions
        are active at the instant that a backend has written its commit
        record.
       </para>
      </listitem>
     </varlistentry>

     <varlistentry>
      <term><varname>COMMIT_SIBLINGS</varname> (<type>integer</type>)</term>
      <listitem>
       <para>
        Minimum number of concurrent open transactions to require before
        performing the <varname>COMMIT_DELAY</> delay. A larger value
        makes it more probable that at least one other transaction will
        become ready to commit during the delay interval.
       </para>
      </listitem>
     </varlistentry>

     <varlistentry>
      <term><varname>WAL_BUFFERS</varname> (<type>integer</type>)</term>
      <listitem>
       <para>
        Number of disk-page buffers in shared memory for WAL logging.
	This option can only be set at server start.
       </para>
      </listitem>
     </varlistentry>

     <varlistentry>
      <term><varname>WAL_DEBUG</varname> (<type>integer</type>)</term>
      <listitem>
       <para>
        If non-zero, turn on WAL-related debugging output on standard
        error.
       </para>
      </listitem>
     </varlistentry>

     <varlistentry>
      <term><varname>WAL_FILES</varname> (<type>integer</type>)</term>
      <listitem>
       <para>
        Number of log files that are created in advance at checkpoint
        time.  This option can only be set at server start or in the
	<filename>postgresql.conf</filename> file.
       </para>
      </listitem>
     </varlistentry>

     <varlistentry>
      <term><varname>WAL_SYNC_METHOD</varname> (<type>string</type>)</term>
      <listitem>
       <para>
        Method used for forcing WAL updates out to disk.  Possible
	values are
	<literal>FSYNC</> (call <function>fsync()</> at each commit),
	<literal>FDATASYNC</> (call <function>fdatasync()</> at each commit),
	<literal>OPEN_SYNC</> (write WAL files with <function>open()</> option <symbol>O_SYNC</>), or
	<literal>OPEN_DATASYNC</> (write WAL files with <function>open()</> option <symbol>O_DSYNC</>).
	Not all of these choices are available on all platforms.
        This option can only be set at server start or in the
	<filename>postgresql.conf</filename> file.
       </para>
      </listitem>
     </varlistentry>
    </variablelist>
    </para>
   </sect2>


   <sect2 id="runtime-config-short">
    <title>Short options</title>
   <para>
    For convenience there are also single letter option switches
    available for many parameters. They are described in the following
    table.

    <table>
     <title>Short option key</title>
     <tgroup cols="3">
      <colspec colnum="3" align="center">
      <thead>
       <row>
        <entry>Short option</entry>
        <entry>Equivalent</entry>
        <entry>Remark</entry>
       </row>
      </thead>
      <tbody>
       <row>
        <entry><option>-B <replaceable>x</replaceable></option></entry>
        <entry><literal>shared_buffers = <replaceable>x</replaceable></></entry>
        <entry></entry>
       </row>
       <row>
        <entry><option>-d <replaceable>x</replaceable></option></entry>
        <entry><literal>server_min_messages = <replaceable>DEBUGx</replaceable></></entry>
        <entry></entry>
       </row>
       <row>
        <entry><option>-F</option></entry>
        <entry><literal>fsync = off</></entry>
        <entry></entry>
       </row>
       <row>
        <entry><option>-h <replaceable>x</replaceable></option></entry>
        <entry><literal>virtual_host = <replaceable>x</replaceable></></entry>
        <entry></entry>
       </row>
       <row>
        <entry><option>-i</option></entry>
        <entry><literal>tcpip_socket = on</></entry>
        <entry></entry>
       </row>
       <row>
        <entry><option>-k <replaceable>x</replaceable></option></entry>
        <entry><literal>unix_socket_directory = <replaceable>x</replaceable></></entry>
        <entry></entry>
       </row>
       <row>
        <entry><option>-l</option></entry>
        <entry><literal>ssl = on</></entry>
        <entry></entry>
       </row>
       <row>
        <entry><option>-N <replaceable>x</replaceable></option></entry>
        <entry><literal>max_connections = <replaceable>x</replaceable></></entry>
        <entry></entry>
       </row>
       <row>
        <entry><option>-p <replaceable>x</replaceable></option></entry>
        <entry><literal>port = <replaceable>x</replaceable></></entry>
        <entry></entry>
       </row>

       <row>
        <entry><option>-fi</option>, <option>-fh</option>, <option>-fm</option>, <option>-fn</option>, <option>-fs</option>, <option>-ft</option></entry>
        <entry><literal>enable_indexscan=off</>, <literal>enable_hashjoin=off</>,
        <literal>enable_mergejoin=off</>, <literal>enable_nestloop=off</>, <literal>enable_seqscan=off</>,
        <literal>enable_tidscan=off</></entry>
        <entry>*</entry>
       </row>
       <row>
        <entry><option>-S <replaceable>x</replaceable></option></entry>
        <entry><literal>sort_mem = <replaceable>x</replaceable></></entry>
        <entry>*</entry>
       </row>
       <row>
        <entry><option>-s</option></entry>
        <entry><literal>show_query_stats = on</></entry>
        <entry>*</entry>
       </row>
       <row>
        <entry><option>-tpa</option>, <option>-tpl</option>, <option>-te</option></entry>
        <entry><literal>show_parser_stats=on</>, <literal>show_planner_stats=on</>, <literal>show_executor_stats=on</></entry>
        <entry>*</entry>
       </row>
      </tbody>
     </tgroup>
    </table>
    For historical reasons, options marked <quote>*</quote> must be
    passed to the individual backend process via the
    <option>-o</option> postmaster option, for example,
<screen>
$ <userinput>postmaster -o '-S 1024 -s'</userinput>
</screen>
    or via <envar>PGOPTIONS</envar> from the client side, as explained
    above.
   </para>

   </sect2>
 </sect1>


 <sect1 id="kernel-resources">
  <title>Managing Kernel Resources</title>

  <para>
   A large <productname>PostgreSQL</> installation can quickly exhaust
   various operating system resource limits. (On some systems, the
   factory defaults are so low that you don't even need a really
   <quote>large</> installation.) If you have encountered this kind of
   problem, keep reading.
  </para>

  <sect2 id="sysvipc">
   <title>Shared Memory and Semaphores</title>

   <indexterm zone="sysvipc">
    <primary>shared memory</primary>
   </indexterm>

   <indexterm zone="sysvipc">
    <primary>semaphores</primary>
   </indexterm>

   <para>
    Shared memory and semaphores are collectively referred to as
    <quote><systemitem class="osname">System V</>
    <acronym>IPC</></quote> (together with message queues, which are not
    relevant for <productname>PostgreSQL</>). Almost all modern
    operating systems provide these features, but not all of them have
    them turned on or sufficiently sized by default, especially systems
    with BSD heritage. (For the <systemitem class="osname">QNX</> and
    <systemitem class="osname">BeOS</> ports, <productname>PostgreSQL</>
    provides its own replacement implementation of these facilities.)
   </para>

   <para>
    The complete lack of these facilities is usually manifested by an
    <errorname>Illegal system call</> error upon postmaster start. In
    that case there's nothing left to do but to reconfigure your
    kernel -- <productname>PostgreSQL</> won't work without them.
   </para>

   <para>
    When <productname>PostgreSQL</> exceeds one of the various hard
    <acronym>IPC</> limits, the postmaster will refuse to start and
    should leave an instructive error message describing the problem
    encountered and what to do about it. (See also <xref
    linkend="postmaster-start-failures">.) The relevant kernel
    parameters are named consistently across different systems; <xref
    linkend="sysvipc-parameters"> gives an overview. The methods to set
    them, however, vary. Suggestions for some platforms are given below.
    Be warned that it is often necessary to reboot your machine, and
    possibly even recompile the kernel, to change these settings.
   </para>


   <table id="sysvipc-parameters">
    <title><systemitem class="osname">System V</> <acronym>IPC</> parameters</>

    <tgroup cols="3">
     <thead>
      <row>
       <entry>Name</>
       <entry>Description</>
       <entry>Reasonable values</>
      </row>
     </thead>

     <tbody>
      <row>
       <entry><varname>SHMMAX</></>
       <entry>Maximum size of shared memory segment (bytes)</>
       <entry>250kB + 8.2kB * <varname>shared_buffers</> + 14.2kB * <varname>max_connections</> or infinity</entry>
      </row>

      <row>
       <entry><varname>SHMMIN</></>
       <entry>Minimum size of shared memory segment (bytes)</>
       <entry>1</>
      </row>

      <row>
       <entry><varname>SHMALL</></>
       <entry>Total amount of shared memory available (bytes or pages)</>
       <entry>if bytes, same as <varname>SHMMAX</varname>; if pages, <literal>ceil(SHMMAX/PAGE_SIZE)</literal></>
      </row>

      <row>
       <entry><varname>SHMSEG</></>
       <entry>Maximum number of shared memory segments per process</>
       <entry>only 1 segment is needed, but the default is much higher</>
      </row>

       <row>
        <entry><varname>SHMMNI</></>
        <entry>Maximum number of shared memory segments system-wide</>
        <entry>like <varname>SHMSEG</> plus room for other applications</>
       </row>

       <row>
        <entry><varname>SEMMNI</></>
        <entry>Maximum number of semaphore identifiers (i.e., sets)</>
        <entry><literal>&gt;= ceil(max_connections / 16)</literal></>
       </row>

       <row>
        <entry><varname>SEMMNS</></>
        <entry>Maximum number of semaphores system-wide</>
        <entry><literal>ceil(max_connections / 16) * 17</literal> + room for other applications</>
       </row>

       <row>
        <entry><varname>SEMMSL</></>
        <entry>Maximum number of semaphores per set</>
        <entry>&gt;= 17</>
       </row>

       <row>
        <entry><varname>SEMMAP</></>
        <entry>Number of entries in semaphore map</>
        <entry>see text</>
       </row>

       <row>
        <entry><varname>SEMVMX</></>
        <entry>Maximum value of semaphore</>
        <entry>&gt;= 255  (The default is often 32767, don't change unless asked to.)</>
       </row>

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


   <para>
    <indexterm><primary>SHMMAX</primary></indexterm> The most important
    shared memory parameter is <varname>SHMMAX</>, the maximum size, in
    bytes, of a shared memory segment. If you get an error message from
    <function>shmget</> like <errorname>Invalid argument</>, it is
    possible that this limit has been exceeded. The size of the required
    shared memory segment varies both with the number of requested
    buffers (<option>-B</> option) and the number of allowed connections
    (<option>-N</> option), although the former is the most significant.
    (You can, as a temporary solution, lower these settings to eliminate
    the failure.) As a rough approximation, you can estimate the
    required segment size by multiplying the number of buffers and the
    block size (8 kB by default) plus ample overhead (at least half a
    megabyte). Any error message you might get will contain the size of
    the failed allocation request.
   </para>

   <para>
    Less likely to cause problems is the minimum size for shared
    memory segments (<varname>SHMMIN</>), which should be at most
    approximately 256 kB for <productname>PostgreSQL</> (it is
    usually just 1). The maximum number of segments system-wide
    (<varname>SHMMNI</>) or per-process (<varname>SHMSEG</>) should
    not cause a problem unless your system has them set to zero. Some
    systems also have a limit on the total amount of shared memory in
    the system; see the platform-specific instructions below.
   </para>

   <para>
    <productname>PostgreSQL</> uses one semaphore per allowed connection
    (<option>-N</> option), in sets of 16.  Each such set will also
    contain a 17th semaphore which contains a <quote>magic
    number</quote>, to detect collision with semaphore sets used by
    other applications. The maximum number of semaphores in the system
    is set by <varname>SEMMNS</>, which consequently must be at least
    as high as the connection setting plus one extra for each 16
    allowed connections (see the formula in <xref
    linkend="sysvipc-parameters">).  The parameter <varname>SEMMNI</>
    determines the limit on the number of semaphore sets that can
    exist on the system at one time.  Hence this parameter must be at
    least <literal>ceil(max_connections / 16)</>. Lowering the number
    of allowed connections is a temporary workaround for failures,
    which are usually confusingly worded <quote><errorname>No space
    left on device</></>, from the function <function>semget()</>.
   </para>

   <para>
    In some cases it might also be necessary to increase
    <varname>SEMMAP</> to be at least on the order of
    <varname>SEMMNS</>. This parameter defines the size of the semaphore
    resource map, in which each contiguous block of available semaphores
    needs an entry. When a semaphore set is freed it is either added to
    an existing entry that is adjacent to the freed block or it is
    registered under a new map entry. If the map is full, the freed
    semaphores get lost (until reboot). Fragmentation of the semaphore
    space could over time lead to fewer available semaphores than there
    should be.
   </para>

   <para>
    The <varname>SEMMSL</> parameter, which determines how many
    semaphores can be in a set, must be at least 17 for
    <productname>PostgreSQL</>.
   </para>

   <para>
    Various other settings related to <quote>semaphore undo</>, such as
    <varname>SEMMNU</> and <varname>SEMUME</>, are not of concern
    for <productname>PostgreSQL</>.
   </para>


   <para>
    <variablelist>

     <varlistentry>
      <term><systemitem class="osname">BSD/OS</></term>
      <indexterm><primary>BSD/OS</></>
      <listitem>
       <formalpara>
        <title>Shared Memory</>
        <para>
         By default, only 4 MB of shared memory is supported. Keep in
         mind that shared memory is not pageable; it is locked in RAM.
         To increase the number of shared buffers supported by the
         postmaster, add the following to your kernel configuration
         file. A <varname>SHMALL</> value of 1024 represents 4MB of
         shared memory. The following increases the maximum shared
         memory area to 32 MB:
<programlisting>
options "SHMALL=8192"
options "SHMMAX=\(SHMALL*PAGE_SIZE\)"
</programlisting>
        </para>
       </formalpara>

       <para>
        For those running 4.1 or later, just make the above changes,
        recompile the kernel, and reboot. For those running earlier
        releases, use <application>bpatch</> to find the
        <varname>sysptsize</> value in the current kernel. This is
        computed dynamically at boot time.
<screen>
$ <userinput>bpatch -r sysptsize</>
<computeroutput>0x9 = 9</>
</screen>
        Next, add <varname>SYSPTSIZE</> as a hard-coded value in the
        kernel configuration file. Increase the value you found using
        <application>bpatch</>. Add 1 for every additional 4 MB of
        shared memory you desire.
<programlisting>
options "SYSPTSIZE=16"
</programlisting>
        <varname>sysptsize</> cannot be changed by <command>sysctl</command>.
       </para>

       <formalpara>
        <title>Semaphores</>
        <para>
         You may need to increase the number of semaphores. By default,
         <productname>PostgreSQL</> allocates 34 semaphores, which is
         over half the default system total of 60.
        </para>
       </formalpara>

        <para>
        Set the values you want in your kernel configuration file, e.g.:
<programlisting>
options "SEMMNI=40"
options "SEMMNS=240"
options "SEMUME=40"
options "SEMMNU=120"
</programlisting>
       </para>
      </listitem>
     </varlistentry>


     <varlistentry>
      <term><systemitem class="osname">FreeBSD</></term>
      <term><systemitem class="osname">NetBSD</></term>
      <term><systemitem class="osname">OpenBSD</></term>
      <indexterm><primary>FreeBSD</></>
      <indexterm><primary>NetBSD</></>
      <indexterm><primary>OpenBSD</></>
      <listitem>
       <para>
        The options <varname>SYSVSHM</> and <varname>SYSVSEM</> need
        to be enabled when the kernel is compiled. (They are by
        default.) The maximum size of shared memory is determined by
        the option <varname>SHMMAXPGS</> (in pages). The following
        shows an example of how to set the various parameters:
<programlisting>
options         SYSVSHM
options         SHMMAXPGS=4096
options         SHMSEG=256

options         SYSVSEM
options         SEMMNI=256
options         SEMMNS=512
options         SEMMNU=256
options         SEMMAP=256
</programlisting>
        (On <systemitem class="osname">NetBSD</> and <systemitem
        class="osname">OpenBSD</> the key word is actually
        <literal>option</literal> singular.)
       </para>
       <para>
        You may also want to use the <application>sysctl</> setting to
        lock shared memory into RAM and prevent it from being paged out
        to swap.
       </para>
      </listitem>
     </varlistentry>


     <varlistentry>
      <term><systemitem class="osname">HP-UX</></term>
      <indexterm><primary>HP-UX</></>
      <listitem>
       <para>
        The default settings tend to suffice for normal installations.
        On <productname>HP-UX</> 10, the factory default for
        <varname>SEMMNS</> is 128, which might be too low for larger
        database sites.
       </para>
       <para>
        <acronym>IPC</> parameters can be set in the <application>System
        Administration Manager</> (<acronym>SAM</>) under
        <menuchoice><guimenu>Kernel
        Configuration</><guimenuitem>Configurable Parameters</></>. Hit
        <guibutton>Create A New Kernel</> when you're done.
       </para>
      </listitem>
     </varlistentry>


     <varlistentry>
      <term><systemitem class="osname">Linux</></term>
      <indexterm><primary>Linux</></>
      <listitem>
       <para>
        The default shared memory limit (both
        <varname>SHMMAX</varname> and <varname>SHMALL</varname>) is 32
        MB in 2.2 kernels, but it can be changed in the
        <filename>proc</filename> file system (without reboot).  For
        example, to allow 128 MB:
<screen>
<prompt>$</prompt> <userinput>echo 134217728 >/proc/sys/kernel/shmall</userinput>
<prompt>$</prompt> <userinput>echo 134217728 >/proc/sys/kernel/shmmax</userinput>
</screen>
        You could put these commands into a script run at boot-time.
       </para>

       <para>
        Alternatively, you can use
        <citerefentry><refentrytitle>sysctl</refentrytitle>
        <manvolnum>8</manvolnum></citerefentry>, if available, to
        control these parameters.  Look for a file called
        <filename>/etc/sysctl.conf</filename> and add lines like the
        following to it:
<programlisting>
kernel.shmall = 134217728
kernel.shmmax = 134217728
</programlisting>
        This file is usually processed at boot time, but
        <application>sysctl</application> can also be called
        explicitly later.
       </para>

       <para>
        Other parameters are sufficiently sized for any application. If
        you want to see for yourself look in
        <filename>/usr/src/linux/include/asm-<replaceable>xxx</>/shmpara
        m.h</> and <filename>/usr/src/linux/include/linux/sem.h</>.
       </para>
      </listitem>
     </varlistentry>


     <varlistentry>
      <term><systemitem class="osname">SCO OpenServer</></term>
      <indexterm><primary>SCO OpenServer</></>
      <listitem>
       <para>
        In the default configuration, only 512 kB of shared memory per
        segment is allowed, which is about enough for <option>-B 24 -N
        12</>. To increase the setting, first change directory to
        <filename>/etc/conf/cf.d</>. To display the current value of
        <varname>SHMMAX</>, in bytes, run
<programlisting>
./configure -y SHMMAX
</programlisting>
        To set a new value for <varname>SHMMAX</>, run:
<programlisting>
./configure SHMMAX=<replaceable>value</>
</programlisting>
        where <replaceable>value</> is the new value you want to use
        (in bytes). After setting <varname>SHMMAX</>, rebuild the kernel
<programlisting>
./link_unix
</programlisting>
        and reboot.
       </para>
      </listitem>
     </varlistentry>


     <varlistentry>
      <term><systemitem class="osname">Solaris</></term>
      <indexterm><primary>Solaris</></>
      <listitem>
       <para>
        At least in version 2.6, the default maximum size of a shared
        memory segments is too low for <productname>PostgreSQL</>. The
        relevant settings can be changed in <filename>/etc/system</>,
        for example:
<programlisting>
set shmsys:shminfo_shmmax=0x2000000
set shmsys:shminfo_shmmin=1
set shmsys:shminfo_shmmni=256
set shmsys:shminfo_shmseg=256

set semsys:seminfo_semmap=256
set semsys:seminfo_semmni=512
set semsys:seminfo_semmns=512
set semsys:seminfo_semmsl=32
</programlisting>
        You need to reboot for the changes to take effect.
       </para>

       <para>
        See also <ulink
        url="http://www.sunworld.com/swol-09-1997/swol-09-insidesolaris.html"></>
        for information on shared memory under
        <productname>Solaris</>.
       </para>
      </listitem>
     </varlistentry>


     <varlistentry>
      <term><systemitem class="osname">UnixWare</></term>
      <indexterm><primary>UnixWare</></>
      <listitem>
       <para>
        On <productname>UnixWare</> 7, the maximum size for shared
        memory segments is 512 kB in the default configuration. This
        is enough for about <option>-B 24 -N 12</>. To display the
        current value of <varname>SHMMAX</>, run
<programlisting>
/etc/conf/bin/idtune -g SHMMAX
</programlisting>
        which displays the current, default, minimum, and maximum
        values, in bytes. To set a new value for <varname>SHMMAX</>,
        run:
<programlisting>
/etc/conf/bin/idtune SHMMAX <replaceable>value</>
</programlisting>
        where <replaceable>value</> is the new value you want to use
        (in bytes). After setting <varname>SHMMAX</>, rebuild the
        kernel
<programlisting>
/etc/conf/bin/idbuild -B
</programlisting>
        and reboot.
       </para>
      </listitem>
     </varlistentry>

    </variablelist>

   </para>
  </sect2>


  <sect2>
   <title>Resource Limits</title>

   <para>
    Unix-like operating systems enforce various kinds of resource limits
    that might interfere with the operation of your
    <productname>PostgreSQL</productname> server. Of particular
    importance are limits on the number of processes per user, the
    number of open files per process, and the amount of memory available
    to each process. Each of these have a <quote>hard</quote> and a
    <quote>soft</quote> limit. The soft limit is what actually counts
    but it can be changed by the user up to the hard limit. The hard
    limit can only be changed by the root user. The system call
    <function>setrlimit</function> is responsible for setting these
    parameters. The shell's built-in command <command>ulimit</command>
    (Bourne shells) or <command>limit</command> (<application>csh</>) is
    used to control the resource limits from the command line. On
    BSD-derived systems the file <filename>/etc/login.conf</filename>
    controls the various resource limits set during login. See
    <citerefentry><refentrytitle>login.conf</refentrytitle>
    <manvolnum>5</manvolnum></citerefentry> for details. The relevant
    parameters are <varname>maxproc</varname>,
    <varname>openfiles</varname>, and <varname>datasize</varname>. For
    example:
<programlisting>
default:\
...
        :datasize-cur=256M:\
        :maxproc-cur=256:\
        :openfiles-cur=256:\
...
</programlisting>
    (<literal>-cur</literal> is the soft limit.  Append
    <literal>-max</literal> to set the hard limit.)
   </para>

   <para>
    Kernels can also have system-wide limits on some resources.
    <itemizedlist>
     <listitem>
      <para>
      On <productname>Linux</productname>
      <filename>/proc/sys/fs/file-max</filename> determines the
      maximum number of open files that the kernel will support.  It can
      be changed by writing a different number into the file or by
      adding an assignment in <filename>/etc/sysctl.conf</filename>.
      The maximum limit of files per process is fixed at the time the
      kernel is compiled; see
      <filename>/usr/src/linux/Documentation/proc.txt</filename> for
      more information.
      </para>
     </listitem>
    </itemizedlist>
   </para>

   <para>
    The <productname>PostgreSQL</productname> server uses one process
    per connection so you should provide for at least as many processes
    as allowed connections, in addition to what you need for the rest
    of your system.  This is usually not a problem but if you run
    several servers on one machine things might get tight.
   </para>

   <para>
    The factory default limit on open files is often set to
    <quote>socially friendly</quote> values that allow many users to
    coexist on a machine without using an inappropriate fraction of
    the system resources.  If you run many servers on a machine this
    is perhaps what you want, but on dedicated servers you may want to
    raise this limit.
   </para>

   <para>
    On the other side of the coin, some systems allow individual
    processes to open large numbers of files; if more than a few
    processes do so then the system-wide limit can easily be exceeded.
    If you find this happening, and don't want to alter the system-wide
    limit, you can set <productname>PostgreSQL</productname>'s
    <varname>max_files_per_process</varname> configuration parameter to
    limit the consumption of open files.
   </para>
  </sect2>

 </sect1>


 <sect1 id="postmaster-shutdown">
  <title>Shutting down the server</title>

  <para>
   There are several ways to shut down the database server. You control
   the type of shutdown by sending different signals to the server
   process.
   <variablelist>
    <varlistentry>
     <term><systemitem>SIGTERM</systemitem></term>
     <listitem>
      <para>
       After receiving <systemitem>SIGTERM</systemitem>, the postmaster
       disallows new connections, but lets existing backends end their
       work normally. It shuts down only after all of the backends
       terminate normally. This is <firstterm>Smart
       Shutdown</firstterm>.
      </para>
     </listitem>
    </varlistentry>

    <varlistentry>
     <term><systemitem>SIGINT</systemitem></term>
     <listitem>
      <para>
       The postmaster disallows new connections and sends all existing
       backends <systemitem>SIGTERM</systemitem>, which will cause them
       to abort their current transactions and exit promptly. It then
       waits for the backends to exit and finally shuts down. This is
       <firstterm>Fast Shutdown</firstterm>.
      </para>
     </listitem>
    </varlistentry>

    <varlistentry>
     <term><systemitem>SIGQUIT</systemitem></term>
     <listitem>
      <para> This is <firstterm>Immediate Shutdown</firstterm>, which
      will cause the postmaster to send a
      <systemitem>SIGQUIT</systemitem> to all backends and exit
      immediately (without properly shutting itself down). The backends
      likewise exit immediately upon receiving
      <systemitem>SIGQUIT</systemitem>. This will lead to recovery (by
      replaying the WAL log) upon next start-up. This is recommended
      only in emergencies.
      </para>
     </listitem>
    </varlistentry>
   </variablelist>

   <important>
    <para>
     It is best not to use <systemitem>SIGKILL</systemitem> to shut down
     the postmaster. This will prevent the postmaster from releasing
     shared memory and semaphores, which may then have to be done by
     manually.
    </para>
   </important>

   The <acronym>PID</> of the postmaster process can be found using the
   <application>ps</application> program, or from the file
   <filename>postmaster.pid</filename> in the data directory. So for
   example, to do a fast shutdown:
<screen>
$ <userinput>kill -INT `head -1 /usr/local/pgsql/data/postmaster.pid`</userinput>
</screen>
  </para>
  <para>
   The program <application>pg_ctl</application> is a shell script
   that provides a more convenient interface for shutting down the
   postmaster.
  </para>
 </sect1>

 <sect1 id="ssl-tcp">
  <title>Secure TCP/IP Connections with SSL</title>

  <indexterm zone="ssl-tcp">
   <primary>SSL</primary>
  </indexterm>

  <para>
   <productname>PostgreSQL</> has native support for using
   <acronym>SSL</> connections to encrypt client/server communications
   for increased security. This requires
   <productname>OpenSSL</productname> be installed on both client and
   server systems and support enabled at build time (see <xref
   linkend="installation">).
  </para>

  <para>
   With SSL support compiled in, the <productname>PostgreSQL</> server
   can be started with the argument <option>-l</> (ell) to enable
   SSL connections. When starting in SSL mode, the server will look
   for the files <filename>server.key</> and <filename>server.crt</> in
   the data directory.  These files should contain the server private key
   and certificate respectively. These files must be set up correctly
   before an SSL-enabled server can start. If the private key is protected
   with a passphrase, the server will prompt for the passphrase and will
   not start until it has been entered.
  </para>

  <para>
   The server will listen for both standard and SSL connections on the
   same TCP/IP port, and will negotiate with any connecting client on
   whether to use SSL. See <xref linkend="client-authentication"> about
   how to force the server to only use of SSL for certain connections.
  </para>

  <para>
   For details on how to create your server private key and certificate,
   refer to the <productname>OpenSSL</> documentation. A simple
   self-signed certificate can be used to get started for testing, but a
   certificate signed by a <acronym>CA</> (either one of the global
   <acronym>CAs</> or a local one) should be used in production so the
   client can verify the server's identity. To create a quick
   self-signed certificate, use the following
   <productname>OpenSSL</productname> command:
<programlisting>
openssl req -new -text -out cert.req
</programlisting>
   Fill out the information that <command>openssl</> asks for. Make sure
   that you enter the local host name as Common Name; the challenge
   password can be left blank. The script will generate a key that is
   passphrase protected; it will not accept a pass phrase that is less
   than four characters long. To remove the passphrase (as you must if
   you want automatic start-up of the server), run the commands
<programlisting>
openssl rsa -in privkey.pem -out cert.pem
</programlisting>
   Enter the old passphrase to unlock the existing key. Now do
<programlisting>
openssl req -x509 -in cert.req -text -key cert.pem -out cert.cert
cp cert.pem <replaceable>$PGDATA</replaceable>/server.key
cp cert.cert <replaceable>$PGDATA</replaceable>/server.crt
</programlisting>
   to turn the certificate into a self-signed certificate and to copy the
   key and certificate to where the server will look for them.
  </para>
 </sect1>

 <sect1 id="ssh-tunnels">
  <title>Secure TCP/IP Connections with <application>SSH</application> tunnels</title>

  <indexterm zone="ssh-tunnels">
   <primary>ssh</primary>
  </indexterm>

  <note>
   <title>Acknowledgement</title>
   <para>
    Idea taken from an email by Gene Selkov, Jr.
    (<email>selkovjr@mcs.anl.gov</>) written on 1999-09-08 in response
    to a question from Eric Marsden.
   </para>
  </note>

  <para>
   One can use <productname>ssh</productname> to encrypt the network
   connection between clients and a
   <productname>PostgreSQL</productname> server. Done properly, this
   should lead to an adequately secure network connection.
  </para>

  <para>
   First make sure that an <application>ssh</application> server is
   running properly on the same machine as
   <productname>PostgreSQL</productname> and that you can log in using
   <command>ssh</command> as some user. Then you can establish a secure
   tunnel with a command like this from the client machine:
<programlisting>
$ <userinput>ssh -L 3333:foo.com:5432 joe@foo.com</userinput>
</programlisting>
   The first number in the <option>-L</option> argument, 3333, is the
   port number of your end of the tunnel; it can be chosen freely. The
   second number, 5432, is the remote end of the tunnel -- the port
   number your server is using. The name or the address in between
   the port numbers is the host with the database server you are going
   to connect to. In order to connect to the database server using
   this tunnel, you connect to port 3333 on the local machine:
<programlisting>
psql -h localhost -p 3333 template1
</programlisting>
   To the database server it will then look as though you are really
   user <literal>joe@foo.com</literal> and it will use whatever
   authentication procedure was set up for this user. In order for the
   tunnel setup to succeed you must be allowed to connect via
   <command>ssh</command> as <systemitem>joe@foo.com</systemitem>, just
   as if you had attempted to use <command>ssh</command> to set up a
   terminal session.
  </para>

  <tip>
   <para>
    Several other products exist that can provide secure tunnels using
    a procedure similar in concept to the one just described.
   </para>
  </tip>

 </sect1>

</Chapter>

<!-- Keep this comment at the end of the file
Local variables:
mode:sgml
sgml-omittag:nil
sgml-shorttag:t
sgml-minimize-attributes:nil
sgml-always-quote-attributes:t
sgml-indent-step:1
sgml-indent-data:t
sgml-parent-document:nil
sgml-default-dtd-file:"./reference.ced"
sgml-exposed-tags:nil
sgml-local-catalogs:("/usr/lib/sgml/catalog")
sgml-local-ecat-files:nil
End:
-->