<!-- $PostgreSQL: pgsql/doc/src/sgml/runtime.sgml,v 1.307 2005/03/04 20:21:05 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 its 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 accessible to the 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 <literal>nobody</literal> 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, and is assumed throughout this book, but you can use another name if you like. </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.) A database cluster is a collection of databases that is managed 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. (See <xref linkend="managing-databases"> for information about creating new databases within a cluster.) </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 <xref linkend="app-initdb">,<indexterm><primary>initdb</></> which is installed with <productname>PostgreSQL</productname>. The desired file system location of your database cluster 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> As an alternative to the <option>-D</option> option, you can set the environment variable <envar>PGDATA</envar>. <indexterm><primary><envar>PGDATA</envar></primary></indexterm> </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 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 client authentication setup allows any local user to connect to the database and even become the database superuser. If you do not trust other local users, we recommend you use one of <command>initdb</command>'s <option>-W</option>, <option>--pwprompt</option> or <option>--pwfile</option> options to assign a password to the database superuser.<indexterm><primary>password</><secondary>of the superuser</></indexterm> Also, specify <option>-A md5</> or <option>-A password</> so that the default <literal>trust</> authentication mode is not used; or modify the generated <filename>pg_hba.conf</filename> file after running <command>initdb</command>, <emphasis>before</> you start the server for the first time. (Other reasonable approaches include using <literal>ident</literal> authentication or file system permissions to restrict connections. See <xref linkend="client-authentication"> for more information.) </para> <para> <command>initdb</command> also initializes the default locale<indexterm><primary>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">. 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. There is also a performance impact for using locales other than <literal>C</> or <literal>POSIX</>. Therefore, it is important to make this choice correctly the first time. </para> <para> <command>initdb</command> also sets the default character set encoding for the database cluster. Normally this should be chosen to match the locale setting. For details see <xref linkend="multibyte">. </para> </sect1> <sect1 id="postmaster-start"> <title>Starting the Database Server</title> <para> Before anyone can access the database, you must start the database server. The database server program is called <command>postmaster</command>.<indexterm><primary>postmaster</></> The <command>postmaster</command> 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 named by the environment variable <envar>PGDATA</envar>. If that variable is not provided either, it will fail. </para> <para> Normally it is better to start the <command>postmaster</command> in the background. For this, use the usual shell syntax: <screen> $ <userinput>postmaster -D /usr/local/pgsql/data >logfile 2>&1 &</userinput> </screen> It is 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> The <command>postmaster</command> also takes a number of other command line options. For more information, see the <xref linkend="app-postmaster"> reference page and <xref linkend="runtime-config"> below. </para> <para> This shell syntax can get tedious quickly. Therefore the wrapper program <xref linkend="app-pg-ctl"><indexterm><primary>pg_ctl</primary></indexterm> 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 <command>postmaster</command>. <command>pg_ctl</command> is also capable of stopping the server. </para> <para> Normally, you will want to start the database server when the computer boots.<indexterm><primary>booting</><secondary>starting the server during</></> Autostart scripts are operating-system-specific. There are a few distributed with <productname>PostgreSQL</productname> in the <filename>contrib/start-scripts</> directory. Installing one will 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. (In each case be sure to use the proper installation directory and user name where we show generic values.) <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</><secondary>start script</secondary></> </para> </listitem> <listitem> <para> On <productname>OpenBSD</productname>, add the following lines to the file <filename>/etc/rc.local</filename>: <indexterm><primary>OpenBSD</><secondary>start script</secondary></> <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</><secondary>start script</secondary></> <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</><secondary>start script</secondary></> </para> </listitem> <listitem> <para> On <productname>Solaris</productname>, create a file called <filename>/etc/init.d/postgresql</filename> that contains the following line: <indexterm><primary>Solaris</><secondary>start script</secondary></> <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 <filename>S99postgresql</>. </para> </listitem> </itemizedlist> </para> <para> While the <command>postmaster</command> is running, its <acronym>PID</acronym> is stored in the file <filename>postmaster.pid</filename> in the data directory. This is used to prevent multiple <command>postmaster</command> processes running in the same data directory and can also be used for shutting down the <command>postmaster</command> process. </para> <sect2 id="postmaster-start-failures"> <title>Server Start-up Failures</title> <para> There are several common reasons the server might fail to start. Check the server's log file, or start it by hand (without redirecting standard output or standard error) and see what error messages appear. Below we explain some of the most common error messages in more detail. </para> <para> <screen> LOG: could not bind IPv4 socket: Address already in use HINT: Is another postmaster already running on port 5432? If not, wait a few seconds and retry. FATAL: could not create TCP/IP listen socket </screen> This usually means just what it suggests: you tried to start another <command>postmaster</command> 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 <command>postmaster</command> on a reserved port number may draw something like: <screen> $ <userinput>postmaster -p 666</userinput> LOG: could not bind IPv4 socket: Permission denied HINT: Is another postmaster already running on port 666? If not, wait a few seconds and retry. FATAL: could not create TCP/IP listen socket </screen> </para> <para> A message like <screen> FATAL: could not create shared memory segment: Invalid argument DETAIL: Failed system call was shmget(key=5440001, size=4011376640, 03600). </screen> probably means your kernel's limit on the size of shared memory is smaller than the work area <productname>PostgreSQL</productname> is trying to create (4011376640 bytes in this example). Or it could mean that you do not have System-V-style shared memory support configured into your kernel at all. As a temporary workaround, you can try starting the server 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 also see this message when trying to start multiple servers on the same machine, if their total space requested exceeds the kernel limit. </para> <para> An error like <screen> FATAL: could not create semaphores: No space left on device DETAIL: Failed system call was semget(5440126, 17, 03600). </screen> does <emphasis>not</emphasis> mean you've run out of disk space. It means your kernel's limit on the number of <systemitem class="osname">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 server with a reduced number of allowed connections (<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 that 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 to configure the server to allow TCP/IP connections. </para> <para> Alternatively, you'll get this when attempting Unix-domain socket communication to a local server: <screen> psql: could not connect to server: No such file or directory 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 server 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 server 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>of the server</secondary> </indexterm> <para> There are a lot of configuration parameters that affect the behavior of the database system. In this subsection, we describe how to set configuration parameters; the following subsections discuss each parameter in detail. </para> <para> All parameter names are case-insensitive. Every parameter takes a value of one of four types: boolean, integer, floating point, or string. Boolean values may be written as <literal>ON</literal>, <literal>OFF</literal>, <literal>TRUE</literal>, <literal>FALSE</literal>, <literal>YES</literal>, <literal>NO</literal>, <literal>1</literal>, <literal>0</literal> (all case-insensitive) or any unambiguous prefix of these. </para> <para> One way to set these parameters is to edit the file <filename>postgresql.conf</><indexterm><primary>postgresql.conf</></>, which is normally kept in the data directory. (<command>initdb</> installs a default copy there.) An example of what this file might look like is: <programlisting> # This is a comment log_connections = yes log_destination = 'syslog' search_path = '$user, public' </programlisting> One parameter is specified per line. The equal sign between name and value is optional. Whitespace is insignificant and blank lines are ignored. Hash marks (<literal>#</literal>) introduce comments anywhere. Parameter values that are not simple identifiers or numbers must be single-quoted. </para> <para> <indexterm> <primary>SIGHUP</primary> </indexterm> The configuration file is reread whenever the <command>postmaster</command> process receives a <systemitem>SIGHUP</> signal (which is most easily sent by means of <literal>pg_ctl reload</>). The <command>postmaster</command> also propagates this signal to all currently running server processes so that existing sessions also get the new value. Alternatively, you can send the signal to a single server process directly. Some parameters can only be set at server start; any changes to their entries in the configuration file will be ignored until the server is restarted. </para> <para> A second way to set these configuration parameters is to give them as a command line option to the <command>postmaster</command>, such as: <programlisting> postmaster -c log_connections=yes -c log_destination='syslog' </programlisting> Command-line options override any conflicting settings in <filename>postgresql.conf</filename>. Note that this means you won't be able to change the value on-the-fly by editing <filename>postgresql.conf</filename>, so while the command-line method may be convenient, it can cost you flexibility later. </para> <para> Occasionally it is useful to give a command line option to one particular 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 <application>libpq</>-based client application, not just <application>psql</application>.) Note that this won't work for parameters that are fixed when the server is started or that must be specified in <filename>postgresql.conf</filename>. </para> <para> 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 <xref linkend="sql-alteruser" endterm="sql-alteruser-title"> and <xref linkend="sql-alterdatabase" endterm="sql-alterdatabase-title">, respectively, are used to configure these settings. Per-database settings override anything received from the <command>postmaster</command> command-line or the configuration file, and in turn are overridden by per-user settings; both are overridden by per-session options. </para> <para> Some parameters can be changed in individual <acronym>SQL</acronym> sessions with the <xref linkend="SQL-SET" endterm="SQL-SET-title"> command, for example: <screen> SET ENABLE_SEQSCAN TO OFF; </screen> If <command>SET</> is allowed, it overrides all other sources of values for the parameter. Some parameters cannot be changed via <command>SET</command>: for example, if they control behavior that cannot reasonably be changed without restarting <productname>PostgreSQL</productname>. Also, some parameters can be modified via <command>SET</command> or <command>ALTER</> by superusers, but not by ordinary users. </para> <para> The <xref linkend="SQL-SHOW" endterm="SQL-SHOW-title"> command allows inspection of the current values of all parameters. </para> <para> The virtual table <structname>pg_settings</structname> (described in <xref linkend="view-pg-settings">) also allows displaying and updating session run-time parameters. It is equivalent to <command>SHOW</> and <command>SET</>, but can be more convenient to use because it can be joined with other tables, or selected from using any desired selection condition. </para> <sect2 id="runtime-config-file-locations"> <title>File Locations</title> <para> In addition to the <filename>postgresql.conf</filename> file already mentioned, <productname>PostgreSQL</productname> uses two other manually-edited configuration files, which control client authentication (their use is discussed in <xref linkend="client-authentication">). By default, all three configuration files are stored in the database cluster's data directory. The options described in this subsection allow the configuration files to be placed elsewhere. (Doing so can ease administration. In particular it is often easier to ensure that the configuration files are properly backed-up when they are kept separate.) </para> <variablelist> <varlistentry id="guc-data-directory" xreflabel="data_directory"> <term><varname>data_directory</varname> (<type>string</type>)</term> <indexterm> <primary><varname>data_directory</> configuration parameter</primary> </indexterm> <listitem> <para> Specifies the directory to use for data storage. This option can only be set at server start. </para> </listitem> </varlistentry> <varlistentry id="guc-config-file" xreflabel="config_file"> <term><varname>config_file</varname> (<type>string</type>)</term> <indexterm> <primary><varname>config_file</> configuration parameter</primary> </indexterm> <listitem> <para> Specifies the main server configuration file (customarily called <filename>postgresql.conf</>). This option can only be set on the postmaster command line. </para> </listitem> </varlistentry> <varlistentry id="guc-hba-file" xreflabel="hba_file"> <term><varname>hba_file</varname> (<type>string</type>)</term> <indexterm> <primary><varname>hba_file</> configuration parameter</primary> </indexterm> <listitem> <para> Specifies the configuration file for host-based authentication (customarily called <filename>pg_hba.conf</>). This option can only be set at server start. </para> </listitem> </varlistentry> <varlistentry id="guc-ident-file" xreflabel="ident_file"> <term><varname>ident_file</varname> (<type>string</type>)</term> <indexterm> <primary><varname>ident_file</> configuration parameter</primary> </indexterm> <listitem> <para> Specifies the configuration file for <application>ident</> authentication (customarily called <filename>pg_ident.conf</>). This option can only be set at server start. </para> </listitem> </varlistentry> <varlistentry id="guc-external-pid-file" xreflabel="external_pid_file"> <term><varname>external_pid_file</varname> (<type>string</type>)</term> <indexterm> <primary><varname>external_pid_file</> configuration parameter</primary> </indexterm> <listitem> <para> Specifies the name of an additional process-id (PID) file that the <application>postmaster</> should create for use by server administration programs. This option can only be set at server start. </para> </listitem> </varlistentry> </variablelist> <para> In a default installation, none of the above options are set explicitly. Instead, the data directory is specified by the <option>-D</option> command-line option or the <envar>PGDATA</envar> environment variable, and the configuration files are all found within the data directory. </para> <para> If you wish to keep the configuration files elsewhere than the data directory, the postmaster's <option>-D</option> command-line option or <envar>PGDATA</envar> environment variable must point to the directory containing the configuration files, and the <varname>data_directory</> option must be set in <filename>postgresql.conf</filename> (or on the command line) to show where the data directory is actually located. Notice that <varname>data_directory</> overrides <option>-D</option> and <envar>PGDATA</envar> for the location of the data directory, but not for the location of the configuration files. </para> <para> If you wish, you can specify the configuration file names and locations individually using the options <varname>config_file</>, <varname>hba_file</> and/or <varname>ident_file</>. <varname>config_file</> can only be specified on the <command>postmaster</command> command line, but the others can be set within the main configuration file. If all three options plus <varname>data_directory</> are explicitly set, then it is not necessary to specify <option>-D</option> or <envar>PGDATA</envar>. </para> <para> When setting any of these options, a relative path will be interpreted with respect to the directory in which the <command>postmaster</command> is started. </para> </sect2> <sect2 id="runtime-config-connection"> <title>Connections and Authentication</title> <sect3 id="runtime-config-connection-settings"> <title>Connection Settings</title> <variablelist> <varlistentry id="guc-listen-addresses" xreflabel="listen_addresses"> <term><varname>listen_addresses</varname> (<type>string</type>)</term> <indexterm> <primary><varname>listen_addresses</> configuration parameter</primary> </indexterm> <listitem> <para> Specifies the TCP/IP address(es) on which the server is to listen for connections from client applications. The value takes the form of a comma-separated list of host names and/or numeric IP addresses. The special entry <literal>*</> corresponds to all available IP interfaces. If the list is empty, the server does not listen on any IP interface at all, in which case only Unix-domain sockets can be used to connect to it. The default value is <systemitem class="systemname">localhost</>, which allows only local <quote>loopback</> connections to be made. This parameter can only be set at server start. </para> </listitem> </varlistentry> <varlistentry id="guc-port" xreflabel="port"> <term><varname>port</varname> (<type>integer</type>)</term> <indexterm> <primary><varname>port</> configuration parameter</primary> </indexterm> <listitem> <para> The TCP port the server listens on; 5432 by default. Note that the same port number is used for all IP addresses the server listens on. This parameter can only be set at server start. </para> </listitem> </varlistentry> <varlistentry id="guc-max-connections" xreflabel="max_connections"> <term><varname>max_connections</varname> (<type>integer</type>)</term> <indexterm> <primary><varname>max_connections</> configuration parameter</primary> </indexterm> <listitem> <para> Determines the maximum number of concurrent connections to the database server. The default is typically 100, but may be less if your kernel settings will not support it (as determined during <application>initdb</>). This parameter can only be set at server start. </para> <para> Increasing this parameter may cause <productname>PostgreSQL</> to request more <systemitem class="osname">System V</> shared memory or semaphores than your operating system's default configuration allows. See <xref linkend="sysvipc"> for information on how to adjust those parameters, if necessary. </para> </listitem> </varlistentry> <varlistentry id="guc-superuser-reserved-connections" xreflabel="superuser_reserved_connections"> <term><varname>superuser_reserved_connections</varname> (<type>integer</type>)</term> <indexterm> <primary><varname>superuser_reserved_connections</> configuration parameter</primary> </indexterm> <listitem> <para> Determines the number of connection <quote>slots</quote> that are reserved for connections by <productname>PostgreSQL</> superusers. At most <xref linkend="guc-max-connections"> connections can ever be active simultaneously. Whenever the number of active concurrent connections is at least <varname>max_connections</> minus <varname>superuser_reserved_connections</varname>, new connections will be accepted only for superusers. </para> <para> The default value is 2. The value must be less than the value of <varname>max_connections</varname>. This parameter can only be set at server start. </para> </listitem> </varlistentry> <varlistentry id="guc-unix-socket-directory" xreflabel="unix_socket_directory"> <term><varname>unix_socket_directory</varname> (<type>string</type>)</term> <indexterm> <primary><varname>unix_socket_directory</> configuration parameter</primary> </indexterm> <listitem> <para> Specifies the directory of the Unix-domain socket on which the server is to listen for connections from client applications. The default is normally <filename>/tmp</filename>, but can be changed at build time. This parameter can only be set at server start. </para> </listitem> </varlistentry> <varlistentry id="guc-unix-socket-group" xreflabel="unix_socket_group"> <term><varname>unix_socket_group</varname> (<type>string</type>)</term> <indexterm> <primary><varname>unix_socket_group</> configuration parameter</primary> </indexterm> <listitem> <para> Sets the owning group of the Unix-domain socket. (The owning user of the socket is always the user that starts the server.) In combination with the option <varname>unix_socket_permissions</varname> this can be used as an additional access control mechanism for Unix-domain connections. 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 id="guc-unix-socket-permissions" xreflabel="unix_socket_permissions"> <term><varname>unix_socket_permissions</varname> (<type>integer</type>)</term> <indexterm> <primary><varname>unix_socket_permissions</> configuration parameter</primary> </indexterm> <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 a 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 <varname>unix_socket_group</varname>) and <literal>0700</literal> (only user). (Note that for a Unix-domain socket, only write permission matters and so 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 id="guc-rendezvous-name" xreflabel="rendezvous_name"> <term><varname>rendezvous_name</varname> (<type>string</type>)</term> <indexterm> <primary><varname>rendezvous_name</> configuration parameter</primary> </indexterm> <listitem> <para> Specifies the <productname>Rendezvous</productname> broadcast name. By default, the computer name is used, specified as an empty string ''. This option is ignored if the server was not compiled with <productname>Rendezvous</productname> support. This option can only be set at server start. </para> </listitem> </varlistentry> </variablelist> </sect3> <sect3 id="runtime-config-connection-security"> <title>Security and Authentication</title> <variablelist> <varlistentry id="guc-authentication-timeout" xreflabel="authentication_timeout"> <term><varname>authentication_timeout</varname> (<type>integer</type>)</term> <indexterm><primary>timeout</><secondary>client authentication</></indexterm> <indexterm><primary>client authentication</><secondary>timeout during</></indexterm> <indexterm> <primary><varname>authentication_timeout</> configuration parameter</primary> </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. The default is 60. </para> </listitem> </varlistentry> <varlistentry id="guc-ssl" xreflabel="ssl"> <term><varname>ssl</varname> (<type>boolean</type>)</term> <indexterm> <primary><varname>ssl</> configuration parameter</primary> </indexterm> <listitem> <para> Enables <acronym>SSL</> connections. Please read <xref linkend="ssl-tcp"> before using this. The default is off. This parameter can only be set at server start. </para> </listitem> </varlistentry> <varlistentry id="guc-password-encryption" xreflabel="password_encryption"> <term><varname>password_encryption</varname> (<type>boolean</type>)</term> <indexterm> <primary><varname>password_encryption</> configuration parameter</primary> </indexterm> <listitem> <para> When a password is specified in <xref linkend="sql-createuser" endterm="sql-createuser-title"> or <xref linkend="sql-alteruser" endterm="sql-alteruser-title"> without writing either <literal>ENCRYPTED</> or <literal>UNENCRYPTED</>, this option determines whether the password is to be encrypted. The default is on (encrypt the password). </para> </listitem> </varlistentry> <varlistentry id="guc-krb-server-keyfile" xreflabel="krb_server_keyfile"> <term><varname>krb_server_keyfile</varname> (<type>string</type>)</term> <indexterm> <primary><varname>krb_server_keyfile</> configuration parameter</primary> </indexterm> <listitem> <para> Sets the location of the Kerberos server key file. See <xref linkend="kerberos-auth"> for details. </para> </listitem> </varlistentry> <varlistentry id="guc-db-user-namespace" xreflabel="db_user_namespace"> <term><varname>db_user_namespace</varname> (<type>boolean</type>)</term> <indexterm> <primary><varname>db_user_namespace</> configuration parameter</primary> </indexterm> <listitem> <para> This allows per-database user names. It is off by default. </para> <para> If this is on, you should create users as <literal>username@dbname</>. When <literal>username</> is passed by a connecting client, <literal>@</> and the database name is appended to the user name and that database-specific user name is looked up by the server. Note that when you create users with names containing <literal>@</> within the SQL environment, you will need to quote the user name. </para> <para> With this option enabled, you can still create ordinary global users. Simply append <literal>@</> when specifying the user name in the client. The <literal>@</> will be stripped off before the user name is looked up by the server. </para> <note> <para> This feature is intended as a temporary measure until a complete solution is found. At that time, this option will be removed. </para> </note> </listitem> </varlistentry> </variablelist> </sect3> </sect2> <sect2 id="runtime-config-resource"> <title>Resource Consumption</title> <sect3 id="runtime-config-resource-memory"> <title>Memory</title> <variablelist> <varlistentry id="guc-shared-buffers" xreflabel="shared_buffers"> <term><varname>shared_buffers</varname> (<type>integer</type>)</term> <indexterm> <primary><varname>shared_buffers</> configuration parameter</primary> </indexterm> <listitem> <para> Sets the number of shared memory buffers used by the database server. The default is typically 1000, but may be less if your kernel settings will not support it (as determined during <application>initdb</>). Each buffer is 8192 bytes, unless a different value of <symbol>BLCKSZ</symbol> was chosen when building the server. This setting must be at least 16, as well as at least twice the value of <xref linkend="guc-max-connections">; however, settings significantly higher than the minimum are usually needed for good performance. Values of a few thousand are recommended for production installations. This option can only be set at server start. </para> <para> Increasing this parameter may cause <productname>PostgreSQL</> to request more <systemitem class="osname">System V</> shared memory than your operating system's default configuration allows. See <xref linkend="sysvipc"> for information on how to adjust those parameters, if necessary. </para> </listitem> </varlistentry> <varlistentry id="guc-work-mem" xreflabel="work_mem"> <term><varname>work_mem</varname> (<type>integer</type>)</term> <indexterm> <primary><varname>work_mem</> configuration parameter</primary> </indexterm> <listitem> <para> Specifies the amount of memory to be used by internal sort operations and hash tables before switching to temporary disk files. The value is specified in kilobytes, and defaults to 1024 kilobytes (1 MB). Note that for a complex query, several sort or hash operations might be running in parallel; each one will be allowed to use as much memory as this value specifies before it starts to put data into temporary files. Also, several running sessions could be doing such operations concurrently. So the total memory used could be many times the value of <varname>work_mem</varname>; it is necessary to keep this fact in mind when choosing the value. Sort operations are used for <literal>ORDER BY</>, <literal>DISTINCT</>, and merge joins. Hash tables are used in hash joins, hash-based aggregation, and hash-based processing of <literal>IN</> subqueries. </para> </listitem> </varlistentry> <varlistentry id="guc-maintenance-work-mem" xreflabel="maintenance_work_mem"> <term><varname>maintenance_work_mem</varname> (<type>integer</type>)</term> <indexterm> <primary><varname>maintenance_work_mem</> configuration parameter</primary> </indexterm> <listitem> <para> Specifies the maximum amount of memory to be used in maintenance operations, such as <command>VACUUM</command>, <command>CREATE INDEX</>, and <command>ALTER TABLE ADD FOREIGN KEY</>. The value is specified in kilobytes, and defaults to 16384 kilobytes (16 MB). Since only one of these operations can be executed at a time by a database session, and an installation normally doesn't have very many of them happening concurrently, it's safe to set this value significantly larger than <varname>work_mem</varname>. Larger settings may improve performance for vacuuming and for restoring database dumps. </para> </listitem> </varlistentry> <varlistentry id="guc-max-stack-depth" xreflabel="max_stack_depth"> <term><varname>max_stack_depth</varname> (<type>integer</type>)</term> <indexterm> <primary><varname>max_stack_depth</> configuration parameter</primary> </indexterm> <listitem> <para> Specifies the maximum safe depth of the server's execution stack. The ideal setting for this parameter is the actual stack size limit enforced by the kernel (as set by <literal>ulimit -s</> or local equivalent), less a safety margin of a megabyte or so. The safety margin is needed because the stack depth is not checked in every routine in the server, but only in key potentially-recursive routines such as expression evaluation. Setting the parameter higher than the actual kernel limit will mean that a runaway recursive function can crash an individual backend process. The default setting is 2048 KB (two megabytes), which is conservatively small and unlikely to risk crashes. However, it may be too small to allow execution of complex functions. </para> </listitem> </varlistentry> </variablelist> </sect3> <sect3 id="runtime-config-resource-fsm"> <title>Free Space Map</title> <variablelist> <varlistentry id="guc-max-fsm-pages" xreflabel="max_fsm_pages"> <term><varname>max_fsm_pages</varname> (<type>integer</type>)</term> <indexterm> <primary><varname>max_fsm_pages</> configuration parameter</primary> </indexterm> <listitem> <para> Sets the maximum number of disk pages for which free space will be tracked in the shared free-space map. Six bytes of shared memory are consumed for each page slot. This setting must be more than 16 * <varname>max_fsm_relations</varname>. The default is 20000. This option can only be set at server start. </para> </listitem> </varlistentry> <varlistentry id="guc-max-fsm-relations" xreflabel="max_fsm_relations"> <term><varname>max_fsm_relations</varname> (<type>integer</type>)</term> <indexterm> <primary><varname>max_fsm_relations</> configuration parameter</primary> </indexterm> <listitem> <para> Sets the maximum number of relations (tables and indexes) for which free space will be tracked in the shared free-space map. Roughly fifty bytes of shared memory are consumed for each slot. The default is 1000. This option can only be set at server start. </para> </listitem> </varlistentry> </variablelist> </sect3> <sect3 id="runtime-config-resource-kernel"> <title>Kernel Resource Usage</title> <variablelist> <varlistentry id="guc-max-files-per-process" xreflabel="max_files_per_process"> <term><varname>max_files_per_process</varname> (<type>integer</type>)</term> <indexterm> <primary><varname>max_files_per_process</> configuration parameter</primary> </indexterm> <listitem> <para> Sets the maximum number of simultaneously open files allowed to each server subprocess. The default is 1000. If the kernel is enforcing a safe per-process limit, you don't need to worry about this setting. But on some platforms (notably, most BSD systems), the kernel will allow individual processes to open many more files 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. </para> </listitem> </varlistentry> <varlistentry id="guc-preload-libraries" xreflabel="preload_libraries"> <term><varname>preload_libraries</varname> (<type>string</type>)</term> <indexterm> <primary><varname>preload_libraries</> configuration parameter</primary> </indexterm> <listitem> <para> This variable specifies one or more shared libraries that are to be preloaded at server start. A parameterless initialization function can optionally be called for each library. To specify that, add a colon and the name of the initialization function after the library name. For example <literal>'$libdir/mylib:mylib_init'</literal> would cause <literal>mylib</> to be preloaded and <literal>mylib_init</> to be executed. If more than one library is to be loaded, separate their names with commas. </para> <para> If a specified library or initialization function is not found, the server will fail to start. </para> <para> <productname>PostgreSQL</productname> procedural language libraries may be preloaded in this way, typically by using the syntax <literal>'$libdir/plXXX:plXXX_init'</literal> where <literal>XXX</literal> is <literal>pgsql</>, <literal>perl</>, <literal>tcl</>, or <literal>python</>. </para> <para> By preloading a shared library (and initializing it if applicable), the library startup time is avoided when the library is first used. However, the time to start each new server process may increase slightly, even if that process never uses the library. So this option is recommended only for libraries that will be used in most sessions. </para> </listitem> </varlistentry> </variablelist> </sect3> <sect3 id="runtime-config-resource-vacuum-cost"> <title>Cost-Based Vacuum Delay</title> <para> During the execution of <xref linkend="sql-vacuum" endterm="sql-vacuum-title"> and <xref linkend="sql-analyze" endterm="sql-analyze-title"> commands, the system maintains an internal counter that keeps track of the estimated cost of the various I/O operations that are performed. When the accumulated cost reaches a limit (specified by <varname>vacuum_cost_limit</varname>), the process performing the operation will sleep for a while (specified by <varname>vacuum_cost_delay</varname>). Then it will reset the counter and continue execution. </para> <para> The intent of this feature is to allow administrators to reduce the I/O impact of these commands on concurrent database activity. There are many situations in which it is not very important that maintenance commands like <command>VACUUM</command> and <command>ANALYZE</command> finish quickly; however, it is usually very important that these commands do not significantly interfere with the ability of the system to perform other database operations. Cost-based vacuum delay provides a way for administrators to achieve this. </para> <para> This feature is disabled by default. To enable it, set the <varname>vacuum_cost_delay</varname> variable to a nonzero value. </para> <variablelist> <varlistentry id="guc-vacuum-cost-delay" xreflabel="vacuum_cost_delay"> <term><varname>vacuum_cost_delay</varname> (<type>integer</type>)</term> <indexterm> <primary><varname>vacuum_cost_delay</> configuration parameter</primary> </indexterm> <listitem> <para> The length of time, in milliseconds, that the process will sleep when the cost limit has been exceeded. The default value is 0, which disables the cost-based vacuum delay feature. Positive values enable cost-based vacuuming. Note that on many systems, the effective resolution of sleep delays is 10 milliseconds; setting <varname>vacuum_cost_delay</varname> to a value that is not a multiple of 10 may have the same results as setting it to the next higher multiple of 10. </para> </listitem> </varlistentry> <varlistentry id="guc-vacuum-cost-page-hit" xreflabel="vacuum_cost_page_hit"> <term><varname>vacuum_cost_page_hit</varname> (<type>integer</type>)</term> <indexterm> <primary><varname>vacuum_cost_page_hit</> configuration parameter</primary> </indexterm> <listitem> <para> The estimated cost for vacuuming a buffer found in the shared buffer cache. It represents the cost to lock the buffer pool, lookup the shared hash table and scan the content of the page. The default value is 1. </para> </listitem> </varlistentry> <varlistentry id="guc-vacuum-cost-page-miss" xreflabel="vacuum_cost_page_miss"> <term><varname>vacuum_cost_page_miss</varname> (<type>integer</type>)</term> <indexterm> <primary><varname>vacuum_cost_page_miss</> configuration parameter</primary> </indexterm> <listitem> <para> The estimated cost for vacuuming a buffer that has to be read from disk. This represents the effort to lock the buffer pool, lookup the shared hash table, read the desired block in from the disk and scan its content. The default value is 10. </para> </listitem> </varlistentry> <varlistentry id="guc-vacuum-cost-page-dirty" xreflabel="vacuum_cost_page_dirty"> <term><varname>vacuum_cost_page_dirty</varname> (<type>integer</type>)</term> <indexterm> <primary><varname>vacuum_cost_page_dirty</> configuration parameter</primary> </indexterm> <listitem> <para> The estimated cost charged when vacuum modifies a block that was previously clean. It represents the extra I/O required to flush the dirty block out to disk again. The default value is 20. </para> </listitem> </varlistentry> <varlistentry id="guc-vacuum-cost-limit" xreflabel="vacuum_cost_limit"> <term><varname>vacuum_cost_limit</varname> (<type>integer</type>)</term> <indexterm> <primary><varname>vacuum_cost_limit</> configuration parameter</primary> </indexterm> <listitem> <para> The accumulated cost that will cause the vacuuming process to sleep. The default value is 200. </para> </listitem> </varlistentry> </variablelist> <note> <para> There are certain operations that hold critical locks and should therefore complete as quickly as possible. Cost-based vacuum delays do not occur during such operations. Therefore it is possible that the cost accumulates far higher than the specified limit. To avoid uselessly long delays in such cases, the actual delay is calculated as <varname>vacuum_cost_delay</varname> * <varname>accumulated_balance</varname> / <varname>vacuum_cost_limit</varname> with a maximum of <varname>vacuum_cost_delay</varname> * 4. </para> </note> </sect3> <sect3 id="runtime-config-resource-background-writer"> <title>Background Writer</title> <para> Beginning in <productname>PostgreSQL</> 8.0, there is a separate server process called the <firstterm>background writer</>, whose sole function is to issue writes of <quote>dirty</> shared buffers. The intent is that server processes handling user queries should seldom or never have to wait for a write to occur, because the background writer will do it. This arrangement also reduces the performance penalty associated with checkpoints. The background writer will continuously trickle out dirty pages to disk, so that only a few pages will need to be forced out when checkpoint time arrives, instead of the storm of dirty-buffer writes that formerly occurred at each checkpoint. However there is a net overall increase in I/O load, because where a repeatedly-dirtied page might before have been written only once per checkpoint interval, the background writer might write it several times in the same interval. In most situations a continuous low load is preferable to periodic spikes, but the parameters discussed in this section can be used to tune the behavior for local needs. </para> <variablelist> <varlistentry id="guc-bgwriter-delay" xreflabel="bgwriter_delay"> <term><varname>bgwriter_delay</varname> (<type>integer</type>)</term> <indexterm> <primary><varname>bgwriter_delay</> configuration parameter</primary> </indexterm> <listitem> <para> Specifies the delay between activity rounds for the background writer. In each round the writer issues writes for some number of dirty buffers (controllable by the following parameters). It then sleeps for <varname>bgwriter_delay</> milliseconds, and repeats. The default value is 200. Note that on many systems, the effective resolution of sleep delays is 10 milliseconds; setting <varname>bgwriter_delay</> to a value that is not a multiple of 10 may have the same results as setting it to the next higher multiple of 10. This option can only be set at server start or in the <filename>postgresql.conf</filename> file. </para> </listitem> </varlistentry> <varlistentry id="guc-bgwriter-lru-percent" xreflabel="bgwriter_lru_percent"> <term><varname>bgwriter_lru_percent</varname> (<type>floating point</type>)</term> <indexterm> <primary><varname>bgwriter_lru_percent</> configuration parameter</primary> </indexterm> <listitem> <para> To reduce the probability that server processes will need to issue their own writes, the background writer tries to write buffers that are likely to be recycled soon. In each round, it examines up to <varname>bgwriter_lru_percent</> of the buffers that are nearest to being recycled, and writes any that are dirty. The default value is 1.0 (this is a percentage of the total number of shared buffers). This option can only be set at server start or in the <filename>postgresql.conf</filename> file. </para> </listitem> </varlistentry> <varlistentry id="guc-bgwriter-lru-maxpages" xreflabel="bgwriter_lru_maxpages"> <term><varname>bgwriter_lru_maxpages</varname> (<type>integer</type>)</term> <indexterm> <primary><varname>bgwriter_lru_maxpages</> configuration parameter</primary> </indexterm> <listitem> <para> In each round, no more than this many buffers will be written as a result of scanning soon-to-be-recycled buffers. The default value is 5. This option can only be set at server start or in the <filename>postgresql.conf</filename> file. </para> </listitem> </varlistentry> <varlistentry id="guc-bgwriter-all-percent" xreflabel="bgwriter_all_percent"> <term><varname>bgwriter_all_percent</varname> (<type>floating point</type>)</term> <indexterm> <primary><varname>bgwriter_all_percent</> configuration parameter</primary> </indexterm> <listitem> <para> To reduce the amount of work that will be needed at checkpoint time, the background writer also does a circular scan through the entire buffer pool, writing buffers that are found to be dirty. In each round, it examines up to <varname>bgwriter_all_percent</> of the buffers for this purpose. The default value is 0.333 (this is a percentage of the total number of shared buffers). With the default <varname>bgwriter_delay</> setting, this will allow the entire shared buffer pool to be scanned about once per minute. This option can only be set at server start or in the <filename>postgresql.conf</filename> file. </para> </listitem> </varlistentry> <varlistentry id="guc-bgwriter-all-maxpages" xreflabel="bgwriter_all_maxpages"> <term><varname>bgwriter_all_maxpages</varname> (<type>integer</type>)</term> <indexterm> <primary><varname>bgwriter_all_maxpages</> configuration parameter</primary> </indexterm> <listitem> <para> In each round, no more than this many buffers will be written as a result of the scan of the entire buffer pool. (If this limit is reached, the scan stops, and resumes at the next buffer during the next round.) The default value is 5. This option can only be set at server start or in the <filename>postgresql.conf</filename> file. </para> </listitem> </varlistentry> </variablelist> <para> Smaller values of <varname>bgwriter_all_percent</varname> and <varname>bgwriter_all_maxpages</varname> reduce the extra I/O load caused by the background writer, but leave more work to be done at checkpoint time. To reduce load spikes at checkpoints, increase these two values. Similarly, smaller values of <varname>bgwriter_lru_percent</varname> and <varname>bgwriter_lru_maxpages</varname> reduce the extra I/O load caused by the background writer, but make it more likely that server processes will have to issue writes for themselves, delaying interactive queries. To disable background writing entirely, set both <varname>maxpages</varname> values and/or both <varname>percent</varname> values to zero. </para> </sect3> </sect2> <sect2 id="runtime-config-wal"> <title>Write Ahead Log</title> <para> See also <xref linkend="wal-configuration"> for details on WAL tuning. </para> <sect3 id="runtime-config-wal-settings"> <title>Settings</title> <variablelist> <varlistentry id="guc-fsync" xreflabel="fsync"> <indexterm> <primary><varname>fsync</> configuration parameter</primary> </indexterm> <term><varname>fsync</varname> (<type>boolean</type>)</term> <listitem> <para> If this option is on, the <productname>PostgreSQL</> server 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 cluster will recover to a consistent state after an operating system or hardware crash. </para> <para> However, using <function>fsync()</function> results in a performance penalty: when a transaction is committed, <productname>PostgreSQL</productname> must wait for the operating system to flush the write-ahead log to disk. When <varname>fsync</varname> is disabled, the operating system is allowed to do its best in buffering, ordering, and delaying writes. This can result in significantly improved 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. (Crashes of the database server itself are <emphasis>not</> a risk factor here. Only an operating-system-level crash creates a risk of corruption.) </para> <para> Due to the risks involved, there is no universally correct setting for <varname>fsync</varname>. Some administrators always disable <varname>fsync</varname>, while others only turn it off for bulk loads, where there is a clear restart point if something goes wrong, whereas some administrators always leave <varname>fsync</varname> enabled. The default is to enable <varname>fsync</varname>, for maximum reliability. If you trust your operating system, your hardware, and your utility company (or your battery backup), you can consider disabling <varname>fsync</varname>. </para> <para> This option can only be set at server start or in the <filename>postgresql.conf</filename> file. </para> </listitem> </varlistentry> <varlistentry id="guc-wal-sync-method" xreflabel="wal_sync_method"> <term><varname>wal_sync_method</varname> (<type>string</type>)</term> <indexterm> <primary><varname>wal_sync_method</> configuration parameter</primary> </indexterm> <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</>), and <literal>open_datasync</> (write WAL files with <function>open()</> option <symbol>O_DSYNC</>). Not all of these choices are available on all platforms. If <varname>fsync</varname> is off then this setting is irrelevant. This option can only be set at server start or in the <filename>postgresql.conf</filename> file. </para> </listitem> </varlistentry> <varlistentry id="guc-wal-buffers" xreflabel="wal_buffers"> <term><varname>wal_buffers</varname> (<type>integer</type>)</term> <indexterm> <primary><varname>wal_buffers</> configuration parameter</primary> </indexterm> <listitem> <para> Number of disk-page buffers allocated in shared memory for WAL data. The default is 8. The setting need only be large enough to hold the amount of WAL data generated by one typical transaction. This option can only be set at server start. </para> </listitem> </varlistentry> <varlistentry id="guc-commit-delay" xreflabel="commit_delay"> <term><varname>commit_delay</varname> (<type>integer</type>)</term> <indexterm> <primary><varname>commit_delay</> configuration parameter</primary> </indexterm> <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 can allow multiple transactions to be committed with only one <function>fsync()</function> system call, if system load is high enough that additional transactions 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 <varname>commit_siblings</varname> other transactions are active at the instant that a server process has written its commit record. The default is zero (no delay). </para> </listitem> </varlistentry> <varlistentry id="guc-commit-siblings" xreflabel="commit_siblings"> <term><varname>commit_siblings</varname> (<type>integer</type>)</term> <indexterm> <primary><varname>commit_siblings</> configuration parameter</primary> </indexterm> <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. The default is five. </para> </listitem> </varlistentry> </variablelist> </sect3> <sect3 id="runtime-config-wal-checkpoints"> <title>Checkpoints</title> <variablelist> <varlistentry id="guc-checkpoint-segments" xreflabel="checkpoint_segments"> <term><varname>checkpoint_segments</varname> (<type>integer</type>)</term> <indexterm> <primary><varname>checkpoint_segments</> configuration parameter</primary> </indexterm> <listitem> <para> Maximum distance between automatic WAL checkpoints, in log file segments (each segment is normally 16 megabytes). The default is three. This option can only be set at server start or in the <filename>postgresql.conf</filename> file. </para> </listitem> </varlistentry> <varlistentry id="guc-checkpoint-timeout" xreflabel="checkpoint_timeout"> <term><varname>checkpoint_timeout</varname> (<type>integer</type>)</term> <indexterm> <primary><varname>checkpoint_timeout</> configuration parameter</primary> </indexterm> <listitem> <para> Maximum time between automatic WAL checkpoints, in seconds. The default is 300 seconds. This option can only be set at server start or in the <filename>postgresql.conf</> file. </para> </listitem> </varlistentry> <varlistentry id="guc-checkpoint-warning" xreflabel="checkpoint_warning"> <term><varname>checkpoint_warning</varname> (<type>integer</type>)</term> <indexterm> <primary><varname>checkpoint_warning</> configuration parameter</primary> </indexterm> <listitem> <para> Write a message to the server log if checkpoints caused by the filling of checkpoint segment files happen closer together than this many seconds. The default is 30 seconds. Zero turns off the warning. </para> </listitem> </varlistentry> </variablelist> </sect3> <sect3 id="runtime-config-wal-archiving"> <title>Archiving</title> <variablelist> <varlistentry id="guc-archive-command" xreflabel="archive_command"> <term><varname>archive_command</varname> (<type>string</type>)</term> <indexterm> <primary><varname>archive_command</> configuration parameter</primary> </indexterm> <listitem> <para> The shell command to execute to archive a completed segment of the WAL file series. If this is an empty string (the default), WAL archiving is disabled. Any <literal>%p</> in the string is replaced by the absolute path of the file to archive, and any <literal>%f</> is replaced by the file name only. Use <literal>%%</> to embed an actual <literal>%</> character in the command. For more information see <xref linkend="backup-archiving-wal">. This option can only be set at server start or in the <filename>postgresql.conf</filename> file. </para> <para> It is important for the command to return a zero exit status if and only if it succeeds. Examples: <programlisting> archive_command = 'cp "%p" /mnt/server/archivedir/"%f"' archive_command = 'copy "%p" /mnt/server/archivedir/"%f"' # Windows </programlisting> </para> </listitem> </varlistentry> </variablelist> </sect3> </sect2> <sect2 id="runtime-config-query"> <title>Query Planning</title> <sect3 id="runtime-config-query-enable"> <title>Planner Method Configuration</title> <para> These configuration parameters provide a crude method of influencing the query plans chosen by the query optimizer. If the default plan chosen by the optimizer for a particular query is not optimal, a temporary solution may be found by using one of these configuration parameters to force the optimizer to choose a different plan. Turning one of these settings off permanently is seldom a good idea, however. Better ways to improve the quality of the plans chosen by the optimizer include adjusting the <xref linkend="runtime-config-query-constants" endterm="runtime-config-query-constants-title">, running <xref linkend="sql-analyze" endterm="sql-analyze-title"> more frequently, increasing the value of the <xref linkend="guc-default-statistics-target"> configuration parameter, and increasing the amount of statistics collected for specific columns using <command>ALTER TABLE SET STATISTICS</command>. </para> <variablelist> <varlistentry id="guc-enable-hashagg" xreflabel="enable_hashagg"> <term><varname>enable_hashagg</varname> (<type>boolean</type>)</term> <indexterm> <primary><varname>enable_hashagg</> configuration parameter</primary> </indexterm> <listitem> <para> Enables or disables the query planner's use of hashed aggregation plan types. The default is on. </para> </listitem> </varlistentry> <varlistentry id="guc-enable-hashjoin" xreflabel="enable_hashjoin"> <term><varname>enable_hashjoin</varname> (<type>boolean</type>)</term> <indexterm> <primary><varname>enable_hashjoin</> configuration parameter</primary> </indexterm> <listitem> <para> Enables or disables the query planner's use of hash-join plan types. The default is on. </para> </listitem> </varlistentry> <varlistentry id="guc-enable-indexscan" xreflabel="enable_indexscan"> <term><varname>enable_indexscan</varname> (<type>boolean</type>)</term> <indexterm> <primary>index scan</primary> </indexterm> <indexterm> <primary><varname>enable_indexscan</> configuration parameter</primary> </indexterm> <listitem> <para> Enables or disables the query planner's use of index-scan plan types. The default is on. </para> </listitem> </varlistentry> <varlistentry id="guc-enable-mergejoin" xreflabel="enable_mergejoin"> <term><varname>enable_mergejoin</varname> (<type>boolean</type>)</term> <indexterm> <primary><varname>enable_mergejoin</> configuration parameter</primary> </indexterm> <listitem> <para> Enables or disables the query planner's use of merge-join plan types. The default is on. </para> </listitem> </varlistentry> <varlistentry id="guc-enable-nestloop" xreflabel="enable_nestloop"> <term><varname>enable_nestloop</varname> (<type>boolean</type>)</term> <indexterm> <primary><varname>enable_nestloop</> configuration parameter</primary> </indexterm> <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. </para> </listitem> </varlistentry> <varlistentry id="guc-enable-seqscan" xreflabel="enable_seqscan"> <term><varname>enable_seqscan</varname> (<type>boolean</type>)</term> <indexterm> <primary>sequential scan</primary> </indexterm> <indexterm> <primary><varname>enable_seqscan</> configuration parameter</primary> </indexterm> <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. </para> </listitem> </varlistentry> <varlistentry id="guc-enable-sort" xreflabel="enable_sort"> <term><varname>enable_sort</varname> (<type>boolean</type>)</term> <indexterm> <primary><varname>enable_sort</> configuration parameter</primary> </indexterm> <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. </para> </listitem> </varlistentry> <varlistentry id="guc-enable-tidscan" xreflabel="enable_tidscan"> <term><varname>enable_tidscan</varname> (<type>boolean</type>)</term> <indexterm> <primary><varname>enable_tidscan</> configuration parameter</primary> </indexterm> <listitem> <para> Enables or disables the query planner's use of <acronym>TID</> scan plan types. The default is on. </para> </listitem> </varlistentry> </variablelist> </sect3> <sect3 id="runtime-config-query-constants"> <title id="runtime-config-query-constants-title"> Planner Cost Constants </title> <note> <para> Unfortunately, there is no well-defined method for determining ideal values for the family of <quote>cost</quote> variables that appear below. You are encouraged to experiment and share your findings. </para> </note> <variablelist> <varlistentry id="guc-effective-cache-size" xreflabel="effective_cache_size"> <term><varname>effective_cache_size</varname> (<type>floating point</type>)</term> <indexterm> <primary><varname>effective_cache_size</> configuration parameter</primary> </indexterm> <listitem> <para> Sets the planner's assumption about the effective size of the disk cache that is available to a single index scan. This is factored into estimates of the cost of using an index; a higher value makes it more likely index scans will be used, a lower value makes it more likely sequential scans will be used. When setting this parameter you should consider both <productname>PostgreSQL</productname>'s shared buffers and the portion of the kernel's disk cache that will be used for <productname>PostgreSQL</productname> data files. Also, take into account the expected number of concurrent queries using different indexes, since they will have to share the available space. This parameter has no effect on the size of shared memory allocated by PostgreSQL, nor does it reserve kernel disk cache; it is used only for estimation purposes. The value is measured in disk pages, which are normally 8192 bytes each. The default is 1000. </para> </listitem> </varlistentry> <varlistentry id="guc-random-page-cost" xreflabel="random_page_cost"> <term><varname>random_page_cost</varname> (<type>floating point</type>)</term> <indexterm> <primary><varname>random_page_cost</> configuration parameter</primary> </indexterm> <listitem> <para> Sets the planner'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. A higher value makes it more likely a sequential scan will be used, a lower value makes it more likely an index scan will be used. The default is four. </para> </listitem> </varlistentry> <varlistentry id="guc-cpu-tuple-cost" xreflabel="cpu_tuple_cost"> <term><varname>cpu_tuple_cost</varname> (<type>floating point</type>)</term> <indexterm> <primary><varname>cpu_tuple_cost</> configuration parameter</primary> </indexterm> <listitem> <para> Sets the planner's estimate of the cost of processing each row during a query. This is measured as a fraction of the cost of a sequential page fetch. The default is 0.01. </para> </listitem> </varlistentry> <varlistentry id="guc-cpu-index-tuple-cost" xreflabel="cpu_index_tuple_cost"> <term><varname>cpu_index_tuple_cost</varname> (<type>floating point</type>)</term> <indexterm> <primary><varname>cpu_index_tuple_cost</> configuration parameter</primary> </indexterm> <listitem> <para> Sets the planner's estimate of the cost of processing each index row during an index scan. This is measured as a fraction of the cost of a sequential page fetch. The default is 0.001. </para> </listitem> </varlistentry> <varlistentry id="guc-cpu-operator-cost" xreflabel="cpu_operator_cost"> <term><varname>cpu_operator_cost</varname> (<type>floating point</type>)</term> <indexterm> <primary><varname>cpu_operator_cost</> configuration parameter</primary> </indexterm> <listitem> <para> Sets the planner's estimate of the cost of processing each operator in a <literal>WHERE</> clause. This is measured as a fraction of the cost of a sequential page fetch. The default is 0.0025. </para> </listitem> </varlistentry> </variablelist> </sect3> <sect3 id="runtime-config-query-geqo"> <title>Genetic Query Optimizer</title> <variablelist> <varlistentry id="guc-geqo" xreflabel="geqo"> <indexterm> <primary>genetic query optimization</primary> </indexterm> <indexterm> <primary>GEQO</primary> <see>genetic query optimization</see> </indexterm> <indexterm> <primary><varname>geqo</> configuration parameter</primary> </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. The <varname>geqo_threshold</varname> variable provides a more granular way to disable GEQO for certain classes of queries. </para> </listitem> </varlistentry> <varlistentry id="guc-geqo-threshold" xreflabel="geqo_threshold"> <term><varname>geqo_threshold</varname> (<type>integer</type>)</term> <indexterm> <primary><varname>geqo_threshold</> configuration parameter</primary> </indexterm> <listitem> <para> Use genetic query optimization to plan queries with at least this many <literal>FROM</> items involved. (Note that an outer <literal>JOIN</> construct counts as only one <literal>FROM</> item.) The default is 12. For simpler queries it is usually best to use the deterministic, exhaustive planner, but for queries with many tables the deterministic planner takes too long. </para> </listitem> </varlistentry> <varlistentry id="guc-geqo-effort" xreflabel="geqo_effort"> <term><varname>geqo_effort</varname> (<type>integer</type>)</term> <indexterm> <primary><varname>geqo_effort</> configuration parameter</primary> </indexterm> <listitem> <para> Controls the trade off between planning time and query plan efficiency in GEQO. This variable must be an integer in the range from 1 to 10. The default value is 5. Larger values increase the time spent doing query planning, but also increase the likelihood that an efficient query plan will be chosen. </para> <para> <varname>geqo_effort</varname> doesn't actually do anything directly; it is only used to compute the default values for the other variables that influence GEQO behavior (described below). If you prefer, you can set the other parameters by hand instead. </para> </listitem> </varlistentry> <varlistentry id="guc-geqo-pool-size" xreflabel="geqo_pool_size"> <term><varname>geqo_pool_size</varname> (<type>integer</type>)</term> <indexterm> <primary><varname>geqo_pool_size</> configuration parameter</primary> </indexterm> <listitem> <para> Controls the pool size used by GEQO. The pool size is the number of individuals in the genetic population. It must be at least two, and useful values are typically 100 to 1000. If it is set to zero (the default setting) then a suitable default is chosen based on <varname>geqo_effort</varname> and the number of tables in the query. </para> </listitem> </varlistentry> <varlistentry id="guc-geqo-generations" xreflabel="geqo_generations"> <term><varname>geqo_generations</varname> (<type>integer</type>)</term> <indexterm> <primary><varname>geqo_generations</> configuration parameter</primary> </indexterm> <listitem> <para> Controls the number of generations used by GEQO. Generations specifies the number of iterations of the algorithm. It must be at least one, and useful values are in the same range as the pool size. If it is set to zero (the default setting) then a suitable default is chosen based on <varname>geqo_pool_size</varname>. </para> </listitem> </varlistentry> <varlistentry id="guc-geqo-selection-bias" xreflabel="geqo_selection_bias"> <term><varname>geqo_selection_bias</varname> (<type>floating point</type>)</term> <indexterm> <primary><varname>geqo_selection_bias</> configuration parameter</primary> </indexterm> <listitem> <para> Controls the selection bias used by GEQO. The selection bias is the selective pressure within the population. Values can be from 1.50 to 2.00; the latter is the default. </para> </listitem> </varlistentry> </variablelist> </sect3> <sect3 id="runtime-config-query-other"> <title>Other Planner Options</title> <variablelist> <varlistentry id="guc-default-statistics-target" xreflabel="default_statistics_target"> <term><varname>default_statistics_target</varname> (<type>integer</type>)</term> <indexterm> <primary><varname>default_statistics_target</> configuration parameter</primary> </indexterm> <listitem> <para> Sets the default statistics target for table columns that have not had a column-specific target set via <command>ALTER TABLE SET STATISTICS</>. Larger values increase the time needed to do <command>ANALYZE</>, but may improve the quality of the planner's estimates. The default is 10. For more information on the use of statistics by the <productname>PostgreSQL</> query planner, refer to <xref linkend="planner-stats">. </para> </listitem> </varlistentry> <varlistentry id="guc-from-collapse-limit" xreflabel="from_collapse_limit"> <term><varname>from_collapse_limit</varname> (<type>integer</type>)</term> <indexterm> <primary><varname>from_collapse_limit</> configuration parameter</primary> </indexterm> <listitem> <para> The planner will merge sub-queries into upper queries if the resulting <literal>FROM</literal> list would have no more than this many items. Smaller values reduce planning time but may yield inferior query plans. The default is 8. It is usually wise to keep this less than <xref linkend="guc-geqo-threshold">. </para> </listitem> </varlistentry> <varlistentry id="guc-join-collapse-limit" xreflabel="join_collapse_limit"> <term><varname>join_collapse_limit</varname> (<type>integer</type>)</term> <indexterm> <primary><varname>join_collapse_limit</> configuration parameter</primary> </indexterm> <listitem> <para> The planner will rewrite explicit inner <literal>JOIN</> constructs into lists of <literal>FROM</> items whenever a list of no more than this many items in total would result. Prior to <productname>PostgreSQL</> 7.4, joins specified via the <literal>JOIN</literal> construct would never be reordered by the query planner. The query planner has subsequently been improved so that inner joins written in this form can be reordered; this configuration parameter controls the extent to which this reordering is performed. <note> <para> At present, the order of outer joins specified via the <literal>JOIN</> construct is never adjusted by the query planner; therefore, <varname>join_collapse_limit</> has no effect on this behavior. The planner may be improved to reorder some classes of outer joins in a future release of <productname>PostgreSQL</productname>. </para> </note> </para> <para> By default, this variable is set the same as <varname>from_collapse_limit</varname>, which is appropriate for most uses. Setting it to 1 prevents any reordering of inner <literal>JOIN</>s. Thus, the explicit join order specified in the query will be the actual order in which the relations are joined. The query planner does not always choose the optimal join order; advanced users may elect to temporarily set this variable to 1, and then specify the join order they desire explicitly. Another consequence of setting this variable to 1 is that the query planner will behave more like the <productname>PostgreSQL</productname> 7.3 query planner, which some users might find useful for backward compatibility reasons. </para> <para> Setting this variable to a value between 1 and <varname>from_collapse_limit</varname> might be useful to trade off planning time against the quality of the chosen plan (higher values produce better plans). </para> </listitem> </varlistentry> </variablelist> </sect3> </sect2> <sect2 id="runtime-config-logging"> <title>Error Reporting and Logging</title> <indexterm zone="runtime-config-logging"> <primary>server log</primary> </indexterm> <sect3 id="runtime-config-logging-where"> <title>Where to log</title> <indexterm zone="runtime-config-logging-where"> <primary>where to log</primary> </indexterm> <variablelist> <varlistentry id="guc-log-destination" xreflabel="log_destination"> <term><varname>log_destination</varname> (<type>string</type>)</term> <indexterm> <primary><varname>log_destination</> configuration parameter</primary> </indexterm> <listitem> <para> <productname>PostgreSQL</productname> supports several methods for logging server messages, including <systemitem>stderr</systemitem> and <systemitem>syslog</systemitem>. On Windows, <systemitem>eventlog</systemitem> is also supported. Set this option to a list of desired log destinations separated by commas. The default is to log to <systemitem>stderr</systemitem> only. This option can only be set at server start or in the <filename>postgresql.conf</filename> configuration file. </para> </listitem> </varlistentry> <varlistentry id="guc-redirect-stderr" xreflabel="redirect_stderr"> <term><varname>redirect_stderr</varname> (<type>boolean</type>)</term> <indexterm> <primary><varname>redirect_stderr</> configuration parameter</primary> </indexterm> <listitem> <para> This option allows messages sent to <application>stderr</> to be captured and redirected into log files. This option, in combination with logging to <application>stderr</>, is often more useful than logging to <application>syslog</>, since some types of messages may not appear in <application>syslog</> output (a common example is dynamic-linker failure messages). This option can only be set at server start. </para> </listitem> </varlistentry> <varlistentry id="guc-log-directory" xreflabel="log_directory"> <term><varname>log_directory</varname> (<type>string</type>)</term> <indexterm> <primary><varname>log_directory</> configuration parameter</primary> </indexterm> <listitem> <para> When <varname>redirect_stderr</> is enabled, this option determines the directory in which log files will be created. It may be specified as an absolute path, or relative to the cluster data directory. This option can only be set at server start or in the <filename>postgresql.conf</filename> configuration file. </para> </listitem> </varlistentry> <varlistentry id="guc-log-filename" xreflabel="log_filename"> <term><varname>log_filename</varname> (<type>string</type>)</term> <indexterm> <primary><varname>log_filename</> configuration parameter</primary> </indexterm> <listitem> <para> When <varname>redirect_stderr</varname> is enabled, this option sets the file names of the created log files. The value is treated as a <systemitem>strftime</systemitem> pattern, so <literal>%</literal>-escapes can be used to specify time-varying file names. If no <literal>%</literal>-escapes are present, <productname>PostgreSQL</productname> will append the epoch of the new log file's open time. For example, if <varname>log_filename</varname> were <literal>server_log</literal>, then the chosen file name would be <literal>server_log.1093827753</literal> for a log starting at Sun Aug 29 19:02:33 2004 MST. This option can only be set at server start or in the <filename>postgresql.conf</filename> configuration file. </para> </listitem> </varlistentry> <varlistentry id="guc-log-rotation-age" xreflabel="log_rotation_age"> <term><varname>log_rotation_age</varname> (<type>integer</type>)</term> <indexterm> <primary><varname>log_rotation_age</> configuration parameter</primary> </indexterm> <listitem> <para> When <varname>redirect_stderr</varname> is enabled, this option determines the maximum lifetime of an individual log file. After this many minutes have elapsed, a new log file will be created. Set to zero to disable time-based creation of new log files. This option can only be set at server start or in the <filename>postgresql.conf</filename> configuration file. </para> </listitem> </varlistentry> <varlistentry id="guc-log-rotation-size" xreflabel="log_rotation_size"> <term><varname>log_rotation_size</varname> (<type>integer</type>)</term> <indexterm> <primary><varname>log_rotation_size</> configuration parameter</primary> </indexterm> <listitem> <para> When <varname>redirect_stderr</varname> is enabled, this option determines the maximum size of an individual log file. After this many kilobytes have been emitted into a log file, a new log file will be created. Set to zero to disable size-based creation of new log files. This option can only be set at server start or in the <filename>postgresql.conf</filename> configuration file. </para> </listitem> </varlistentry> <varlistentry id="guc-log-truncate-on-rotation" xreflabel="log_truncate_on_rotation"> <term><varname>log_truncate_on_rotation</varname> (<type>boolean</type>)</term> <indexterm> <primary><varname>log_truncate_on_rotation</> configuration parameter</primary> </indexterm> <listitem> <para> When <varname>redirect_stderr</varname> is enabled, this option will cause <productname>PostgreSQL</productname> to truncate (overwrite), rather than append to, any existing log file of the same name. However, truncation will occur only when a new file is being opened due to time-based rotation, not during server startup or size-based rotation. When false, pre-existing files will be appended to in all cases. For example, using this option in combination with a <varname>log_filename</varname> like <literal>postgresql-%H.log</literal> would result in generating twenty-four hourly log files and then cyclically overwriting them. This option can only be set at server start or in the <filename>postgresql.conf</filename> configuration file. </para> <para> Example: To keep 7 days of logs, one log file per day named <literal>server_log.Mon</literal>, <literal>server_log.Tue</literal>, etc, and automatically overwrite last week's log with this week's log, set <varname>log_filename</varname> to <literal>server_log.%a</literal>, <varname>log_truncate_on_rotation</varname> to <literal>true</literal>, and <varname>log_rotation_age</varname> to <literal>1440</literal>. </para> <para> Example: To keep 24 hours of logs, one log file per hour, but also rotate sooner if the log file size exceeds 1GB, set <varname>log_filename</varname> to <literal>server_log.%H%M</literal>, <varname>log_truncate_on_rotation</varname> to <literal>true</literal>, <varname>log_rotation_age</varname> to <literal>60</literal>, and <varname>log_rotation_size</varname> to <literal>1000000</literal>. Including <literal>%M</> in <varname>log_filename</varname> allows any size-driven rotations that may occur to select a filename different from the hour's initial filename. </para> </listitem> </varlistentry> <varlistentry id="guc-syslog-facility" xreflabel="syslog_facility"> <term><varname>syslog_facility</varname> (<type>string</type>)</term> <indexterm> <primary><varname>syslog_facility</> configuration parameter</primary> </indexterm> <listitem> <para> When logging to <application>syslog</> is enabled, this option determines the <application>syslog</application> <quote>facility</quote> to be used. You may choose from <literal>LOCAL0</>, <literal>LOCAL1</>, <literal>LOCAL2</>, <literal>LOCAL3</>, <literal>LOCAL4</>, <literal>LOCAL5</>, <literal>LOCAL6</>, <literal>LOCAL7</>; the default is <literal>LOCAL0</>. See also the documentation of your system's <application>syslog</application> daemon. This option can only be set at server start. </para> </listitem> </varlistentry> <varlistentry id="guc-syslog-ident" xreflabel="syslog_ident"> <term><varname>syslog_ident</varname> (<type>string</type>)</term> <indexterm> <primary><varname>syslog_identity</> configuration parameter</primary> </indexterm> <listitem> <para> When logging to <application>syslog</> is enabled, this option determines the program name used to identify <productname>PostgreSQL</productname> messages in <application>syslog</application> logs. The default is <literal>postgres</literal>. This option can only be set at server start. </para> </listitem> </varlistentry> </variablelist> </sect3> <sect3 id="runtime-config-logging-when"> <title>When To Log</title> <variablelist> <varlistentry id="guc-client-min-messages" xreflabel="client_min_messages"> <term><varname>client_min_messages</varname> (<type>string</type>)</term> <indexterm> <primary><varname>client_min_messages</> configuration parameter</primary> </indexterm> <listitem> <para> Controls which message levels are sent to the client. Valid values are <literal>DEBUG5</>, <literal>DEBUG4</>, <literal>DEBUG3</>, <literal>DEBUG2</>, <literal>DEBUG1</>, <literal>LOG</>, <literal>NOTICE</>, <literal>WARNING</>, and <literal>ERROR</>. Each level includes all the levels that follow it. The later the level, the fewer messages are sent. The default is <literal>NOTICE</>. Note that <literal>LOG</> has a different rank here than in <varname>log_min_messages</>. </para> </listitem> </varlistentry> <varlistentry id="guc-log-min-messages" xreflabel="log_min_messages"> <term><varname>log_min_messages</varname> (<type>string</type>)</term> <indexterm> <primary><varname>log_min_messages</> configuration parameter</primary> </indexterm> <listitem> <para> Controls which message levels are written to the server log. 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</>. Each level includes all the levels that follow it. The later the level, the fewer messages are sent to the log. The default is <literal>NOTICE</>. Note that <literal>LOG</> has a different rank here than in <varname>client_min_messages</>. Only superusers can change this setting. </para> </listitem> </varlistentry> <varlistentry id="guc-log-error-verbosity" xreflabel="log_error_verbosity"> <term><varname>log_error_verbosity</varname> (<type>string</type>)</term> <indexterm> <primary><varname>log_error_verbosity</> configuration parameter</primary> </indexterm> <listitem> <para> Controls the amount of detail written in the server log for each message that is logged. Valid values are <literal>TERSE</>, <literal>DEFAULT</>, and <literal>VERBOSE</>, each adding more fields to displayed messages. Only superusers can change this setting. </para> </listitem> </varlistentry> <varlistentry id="guc-log-min-error-statement" xreflabel="log_min_error_statement"> <term><varname>log_min_error_statement</varname> (<type>string</type>)</term> <indexterm> <primary><varname>log_min_error_statement</> configuration parameter</primary> </indexterm> <listitem> <para> Controls whether or not the SQL statement that causes an error condition will also be recorded in the server log. All SQL statements that cause an error of the specified level or higher are logged. The default is <literal>PANIC</literal> (effectively turning this feature off for normal use). Valid values are <literal>DEBUG5</literal>, <literal>DEBUG4</literal>, <literal>DEBUG3</literal>, <literal>DEBUG2</literal>, <literal>DEBUG1</literal>, <literal>INFO</literal>, <literal>NOTICE</literal>, <literal>WARNING</literal>, <literal>ERROR</literal>, <literal>FATAL</literal>, and <literal>PANIC</literal>. For example, if you set this to <literal>ERROR</literal> then all SQL statements causing errors, fatal errors, or panics will be logged. Enabling this option can be helpful in tracking down the source of any errors that appear in the server log. Only superusers can change this setting. </para> </listitem> </varlistentry> <varlistentry id="guc-log-min-duration-statement" xreflabel="log_min_duration_statement"> <term><varname>log_min_duration_statement</varname> (<type>integer</type>)</term> <indexterm> <primary><varname>log_min_duration_statement</> configuration parameter</primary> </indexterm> <listitem> <para> Sets a minimum statement execution time (in milliseconds) that causes a statement to be logged. All SQL statements that run for the time specified or longer will be logged with their duration. Setting this to zero will print all queries and their durations. Minus-one (the default) disables the feature. For example, if you set it to <literal>250</literal> then all SQL statements that run 250ms or longer will be logged. Enabling this option can be useful in tracking down unoptimized queries in your applications. Only superusers can change this setting. </para> </listitem> </varlistentry> <varlistentry id="guc-silent-mode" xreflabel="silent_mode"> <term><varname>silent_mode</varname> (<type>boolean</type>)</term> <indexterm> <primary><varname>silent_mode</> configuration parameter</primary> </indexterm> <listitem> <para> Runs the server silently. If this option is set, the server will automatically run in background and any controlling terminals are disassociated (same effect as <command>postmaster</>'s <option>-S</option> option). The server's standard output and standard error are redirected to <literal>/dev/null</>, so any messages sent to them will be lost. Unless <application>syslog</> logging is selected or <varname>redirect_stderr</> is enabled, using this option is discouraged because it makes it impossible to see error messages. </para> </listitem> </varlistentry> </variablelist> <para> Here is a list of the various message severity levels used in these settings: <variablelist> <varlistentry> <term><literal>DEBUG[1-5]</literal></term> <listitem> <para> Provides information for use by developers. </para> </listitem> </varlistentry> <varlistentry> <term><literal>INFO</literal></term> <listitem> <para> Provides information implicitly requested by the user, e.g., during <command>VACUUM VERBOSE</>. </para> </listitem> </varlistentry> <varlistentry> <term><literal>NOTICE</literal></term> <listitem> <para> Provides information that may be helpful to users, e.g., truncation of long identifiers and the creation of indexes as part of primary keys. </para> </listitem> </varlistentry> <varlistentry> <term><literal>WARNING</literal></term> <listitem> <para> Provides warnings to the user, e.g., <command>COMMIT</> outside a transaction block. </para> </listitem> </varlistentry> <varlistentry> <term><literal>ERROR</literal></term> <listitem> <para> Reports an error that caused the current command to abort. </para> </listitem> </varlistentry> <varlistentry> <term><literal>LOG</literal></term> <listitem> <para> Reports information of interest to administrators, e.g., checkpoint activity. </para> </listitem> </varlistentry> <varlistentry> <term><literal>FATAL</literal></term> <listitem> <para> Reports an error that caused the current session to abort. </para> </listitem> </varlistentry> <varlistentry> <term><literal>PANIC</literal></term> <listitem> <para> Reports an error that caused all sessions to abort. </para> </listitem> </varlistentry> </variablelist> </para> </sect3> <sect3 id="runtime-config-logging-what"> <title>What To Log</title> <variablelist> <varlistentry> <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> <indexterm> <primary><varname>debug_print_parse</> configuration parameter</primary> </indexterm> <indexterm> <primary><varname>debug_print_rewritten</> configuration parameter</primary> </indexterm> <indexterm> <primary><varname>debug_print_plan</> configuration parameter</primary> </indexterm> <indexterm> <primary><varname>debug_pretty_print</> configuration parameter</primary> </indexterm> <listitem> <para> These options enable various debugging output to be emitted. For each executed query, they print the resulting parse tree, the query rewriter output, or the execution plan. <varname>debug_pretty_print</varname> indents these displays to produce a more readable but much longer output format. <varname>client_min_messages</varname> or <varname>log_min_messages</varname> must be <literal>DEBUG1</literal> or lower to actually send this output to the client or the server log, respectively. These options are off by default. </para> </listitem> </varlistentry> <varlistentry id="guc-log-connections" xreflabel="log_connections"> <term><varname>log_connections</varname> (<type>boolean</type>)</term> <indexterm> <primary><varname>log_connections</> configuration parameter</primary> </indexterm> <listitem> <para> This outputs a line to the server log 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 id="guc-log-disconnections" xreflabel="log_disconnections"> <term><varname>log_disconnections</varname> (<type>boolean</type>)</term> <indexterm> <primary><varname>log_disconnections</> configuration parameter</primary> </indexterm> <listitem> <para> This outputs a line in the server log similar to <varname>log_connections</varname> but at session termination, and includes the duration of the session. This is off by default. This option can only be set at server start or in the <filename>postgresql.conf</filename> configuration file. </para> </listitem> </varlistentry> <varlistentry id="guc-log-duration" xreflabel="log_duration"> <term><varname>log_duration</varname> (<type>boolean</type>)</term> <indexterm> <primary><varname>log_duration</> configuration parameter</primary> </indexterm> <listitem> <para> Causes the duration of every completed statement which satisfies <varname>log_statement</> to be logged. When using this option, if you are not using <application>syslog</>, it is recommended that you log the PID or session ID using <varname>log_line_prefix</> so that you can link the statement to the duration using the process ID or session ID. The default is off. Only superusers can change this setting. </para> </listitem> </varlistentry> <varlistentry id="guc-log-line-prefix" xreflabel="log_line_prefix"> <term><varname>log_line_prefix</varname> (<type>string</type>)</term> <indexterm> <primary><varname>log_line_prefix</> configuration parameter</primary> </indexterm> <listitem> <para> This is a <function>printf</>-style string that is output at the beginning of each log line. The default is an empty string. Each recognized escape is replaced as outlined below - anything else that looks like an escape is ignored. Other characters are copied straight to the log line. Some escapes are only recognised by session processes, and do not apply to background processes such as the postmaster. <application>Syslog</> produces its own time stamp and process ID information, so you probably do not want to use those escapes if you are using <application>syslog</>. This option can only be set at server start or in the <filename>postgresql.conf</filename> configuration file. <informaltable> <tgroup cols="3"> <thead> <row> <entry>Escape</entry> <entry>Effect</entry> <entry>Session only</entry> </row> </thead> <tbody> <row> <entry><literal>%u</literal></entry> <entry>User name</entry> <entry>yes</entry> </row> <row> <entry><literal>%d</literal></entry> <entry>Database name</entry> <entry>yes</entry> </row> <row> <entry><literal>%r</literal></entry> <entry>Remote host name or IP address, and remote port</entry> <entry>yes</entry> </row> <row> <entry><literal>%p</literal></entry> <entry>Process ID</entry> <entry>no</entry> </row> <row> <entry><literal>%t</literal></entry> <entry>Time stamp</entry> <entry>no</entry> </row> <row> <entry><literal>%i</literal></entry> <entry>Command tag: This is the command that generated the log line.</entry> <entry>yes</entry> </row> <row> <entry><literal>%c</literal></entry> <entry>Session ID: A unique identifier for each session. It is 2 4-byte hexadecimal numbers (without leading zeros) separated by a dot. The numbers are the session start time and the process ID, so this can also be used as a space saving way of printing these items.</entry> <entry>yes</entry> </row> <row> <entry><literal>%l</literal></entry> <entry>Number of the log line for each process, starting at 1</entry> <entry>no</entry> </row> <row> <entry><literal>%s</literal></entry> <entry>Session start time stamp</entry> <entry>yes</entry> </row> <row> <entry><literal>%x</literal></entry> <entry>Transaction ID</entry> <entry>yes</entry> </row> <row> <entry><literal>%q</literal></entry> <entry>Does not produce any output, but tells non-session processes to stop at this point in the string. Ignored by session processes.</entry> <entry>no</entry> </row> <row> <entry><literal>%%</literal></entry> <entry>Literal <literal>%</></entry> <entry>no</entry> </row> </tbody> </tgroup> </informaltable> </para> </listitem> </varlistentry> <varlistentry id="guc-log-statement" xreflabel="log_statement"> <term><varname>log_statement</varname> (<type>string</type>)</term> <indexterm> <primary><varname>log_statement</> configuration parameter</primary> </indexterm> <listitem> <para> Controls which SQL statements are logged. Valid values are <literal>none</>, <literal>ddl</>, <literal>mod</>, and <literal>all</>. <literal>ddl</> logs all data definition commands like <literal>CREATE</>, <literal>ALTER</>, and <literal>DROP</> commands. <literal>mod</> logs all <literal>ddl</> statements, plus <literal>INSERT</>, <literal>UPDATE</>, <literal>DELETE</>, <literal>TRUNCATE</>, and <literal>COPY FROM</>. <literal>PREPARE</> and <literal>EXPLAIN ANALYZE</> statements are also logged if their contained command is of an appropriate type. </para> <para> The default is <literal>none</>. Only superusers can change this setting. </para> <note> <para> The <command>EXECUTE</command> statement is not considered a <literal>ddl</> or <literal>mod</> statement. When it is logged, only the name of the prepared statement is reported, not the actual prepared statement. </para> <para> When a function is defined in the <application>PL/pgSQL</application>server-side language, any queries executed by the function will only be logged the first time that the function is invoked in a particular session. This is because <application>PL/pgSQL</application> keeps a cache of the query plans produced for the SQL statements in the function. </para> </note> </listitem> </varlistentry> <varlistentry id="guc-log-hostname" xreflabel="log_hostname"> <term><varname>log_hostname</varname> (<type>boolean</type>)</term> <indexterm> <primary><varname>log_hostname</> configuration parameter</primary> </indexterm> <listitem> <para> By default, connection log messages only show the IP address of the connecting host. Turning on this option causes logging of the host name as well. Note that depending on your host name resolution setup this might impose a non-negligible performance penalty. This option can only be set at server start or in the <filename>postgresql.conf</filename> file. </para> </listitem> </varlistentry> </variablelist> </sect3> </sect2> <sect2 id="runtime-config-statistics"> <title>Runtime Statistics</title> <sect3 id="runtime-config-statistics-monitor"> <title>Statistics Monitoring</title> <variablelist> <varlistentry> <term><varname>log_statement_stats</varname> (<type>boolean</type>)</term> <term><varname>log_parser_stats</varname> (<type>boolean</type>)</term> <term><varname>log_planner_stats</varname> (<type>boolean</type>)</term> <term><varname>log_executor_stats</varname> (<type>boolean</type>)</term> <indexterm> <primary><varname>log_statement_stats</> configuration parameter</primary> </indexterm> <indexterm> <primary><varname>log_parser_stats</> configuration parameter</primary> </indexterm> <indexterm> <primary><varname>log_planner_stats</> configuration parameter</primary> </indexterm> <indexterm> <primary><varname>log_executor_stats</> configuration parameter</primary> </indexterm> <listitem> <para> For each query, write performance statistics of the respective module to the server log. This is a crude profiling instrument. <varname>log_statement_stats</varname> reports total statement statistics, while the others report per-module statistics. <varname>log_statement_stats</varname> cannot be enabled together with any of the per-module options. All of these options are disabled by default. Only superusers can change these settings. </para> </listitem> </varlistentry> </variablelist> </sect3> <sect3 id="runtime-config-statistics-collector"> <title>Query and Index Statistics Collector</title> <variablelist> <varlistentry id="guc-stats-start-collector" xreflabel="stats_start_collector"> <term><varname>stats_start_collector</varname> (<type>boolean</type>)</term> <indexterm> <primary><varname>stats_start_collector</> configuration parameter</primary> </indexterm> <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 id="guc-stats-command-string" xreflabel="stats_command_string"> <term><varname>stats_command_string</varname> (<type>boolean</type>)</term> <indexterm> <primary><varname>stats_command_string</> configuration parameter</primary> </indexterm> <listitem> <para> Enables the collection of statistics on the currently executing command of each session, along with the time at which that command began execution. This option is off by default. Note that even when enabled, this information is not visible to all users, only to superusers and the user owning the session being reported on; so it should not represent a security risk. This data can be accessed via the <structname>pg_stat_activity</structname> system view; refer to <xref linkend="monitoring"> for more information. </para> </listitem> </varlistentry> <varlistentry id="guc-stats-block-level" xreflabel="stats_block_level"> <term><varname>stats_block_level</varname> (<type>boolean</type>)</term> <indexterm> <primary><varname>stats_block_level</> configuration parameter</primary> </indexterm> <listitem> <para> Enables the collection of block-level statistics on database activity. This option is disabled by default. If this option is enabled, the data that is produced can be accessed via the <structname>pg_stat</structname> and <structname>pg_statio</structname> family of system views; refer to <xref linkend="monitoring"> for more information. </para> </listitem> </varlistentry> <varlistentry id="guc-stats-row-level" xreflabel="stats_row_level"> <term><varname>stats_row_level</varname> (<type>boolean</type>)</term> <indexterm> <primary><varname>stats_row_level</> configuration parameter</primary> </indexterm> <listitem> <para> Enables the collection of row-level statistics on database activity. This option is disabled by default. If this option is enabled, the data that is produced can be accessed via the <structname>pg_stat</structname> and <structname>pg_statio</structname> family of system views; refer to <xref linkend="monitoring"> for more information. </para> </listitem> </varlistentry> <varlistentry id="guc-stats-reset-on-server-start" xreflabel="stats_reset_on_server_start"> <term><varname>stats_reset_on_server_start</varname> (<type>boolean</type>)</term> <indexterm> <primary><varname>stats_reset_on_server_start</> configuration parameter</primary> </indexterm> <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> </variablelist> </sect3> </sect2> <sect2 id="runtime-config-client"> <title>Client Connection Defaults</title> <sect3 id="runtime-config-client-statement"> <title>Statement Behavior</title> <variablelist> <varlistentry id="guc-search-path" xreflabel="search_path"> <term><varname>search_path</varname> (<type>string</type>)</term> <indexterm> <primary><varname>search_path</> configuration parameter</primary> </indexterm> <indexterm><primary>path</><secondary>for schemas</></> <listitem> <para> This variable specifies the order in which schemas are searched when an object (table, data type, function, etc.) is referenced by a simple name with no schema component. When there are objects of identical names in different schemas, the one found first in the search path is used. An object that is not in any of the schemas in the search path can only be referenced by specifying its containing schema with a qualified (dotted) name. </para> <para> The value for <varname>search_path</varname> has to be a comma-separated list of schema names. If one of the list items is the special value <literal>$user</literal>, then the schema having the name returned by <function>SESSION_USER</> is substituted, if there is such a schema. (If not, <literal>$user</literal> is ignored.) </para> <para> The system catalog schema, <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 schema, <literal>pg_temp_<replaceable>nnn</></>, is implicitly searched before any of these. </para> <para> When objects are created without specifying a particular target schema, they will be placed in the first schema 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 schema named <literal>public</>). This supports shared use of a database (where no users have private schemas, and all share use of <literal>public</>), private per-user schemas, and combinations of these. Other effects can be obtained by altering the default search path setting, either globally or per-user. </para> <para> The current effective value of the search path can be examined via the <acronym>SQL</acronym> function <function>current_schemas()</>. This is not quite the same as examining the value of <varname>search_path</varname>, since <function>current_schemas()</> shows how the requests appearing in <varname>search_path</varname> were resolved. </para> <para> For more information on schema handling, see <xref linkend="ddl-schemas">. </para> </listitem> </varlistentry> <varlistentry id="guc-default-tablespace" xreflabel="default_tablespace"> <term><varname>default_tablespace</varname> (<type>string</type>)</term> <indexterm> <primary><varname>default_tablespace</> configuration parameter</primary> </indexterm> <indexterm><primary>tablespace</><secondary>default</></> <listitem> <para> This variable specifies the default tablespace in which to create objects (tables and indexes) when a <command>CREATE</> command does not explicitly specify a tablespace. </para> <para> The value is either the name of a tablespace, or an empty string to specify using the default tablespace of the current database. If the value does not match the name of any existing tablespace, <productname>PostgreSQL</> will automatically use the default tablespace of the current database. </para> <para> For more information on tablespaces, see <xref linkend="manage-ag-tablespaces">. </para> </listitem> </varlistentry> <varlistentry id="guc-check-function-bodies" xreflabel="check_function_bodies"> <term><varname>check_function_bodies</varname> (<type>boolean</type>)</term> <indexterm> <primary><varname>check_function_bodies</> configuration parameter</primary> </indexterm> <listitem> <para> This parameter is normally true. When set to false, it disables validation of the function body string during <xref linkend="sql-createfunction" endterm="sql-createfunction-title">. Disabling validation is occasionally useful to avoid problems such as forward references when restoring function definitions from a dump. </para> </listitem> </varlistentry> <varlistentry id="guc-default-transaction-isolation" xreflabel="default_transaction_isolation"> <indexterm> <primary>transaction isolation level</primary> </indexterm> <indexterm> <primary><varname>default_transaction_isolation</> configuration parameter</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 uncommitted</quote>, <quote>read committed</quote>, <quote>repeatable read</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 <xref linkend="mvcc"> and <xref linkend="sql-set-transaction"> for more information. </para> </listitem> </varlistentry> <varlistentry id="guc-default-transaction-read-only" xreflabel="default_transaction_read_only"> <indexterm> <primary>read-only transaction</primary> </indexterm> <indexterm> <primary><varname>default_transaction_read_only</> configuration parameter</primary> </indexterm> <term><varname>default_transaction_read_only</varname> (<type>boolean</type>)</term> <listitem> <para> A read-only SQL transaction cannot alter non-temporary tables. This parameter controls the default read-only status of each new transaction. The default is false (read/write). </para> <para> Consult <xref linkend="sql-set-transaction"> for more information. </para> </listitem> </varlistentry> <varlistentry id="guc-statement-timeout" xreflabel="statement_timeout"> <term><varname>statement_timeout</varname> (<type>integer</type>)</term> <indexterm> <primary><varname>statement_timeout</> configuration parameter</primary> </indexterm> <listitem> <para> Abort any statement that takes over the specified number of milliseconds. A value of zero (the default) turns off the limitation. </para> </listitem> </varlistentry> </variablelist> </sect3> <sect3 id="runtime-config-client-format"> <title>Locale and Formatting</title> <variablelist> <varlistentry id="guc-datestyle" xreflabel="DateStyle"> <term><varname>DateStyle</varname> (<type>string</type>)</term> <indexterm> <primary><varname>DateStyle</> configuration parameter</primary> </indexterm> <listitem> <para> Sets the display format for date and time values, as well as the rules for interpreting ambiguous date input values. For historical reasons, this variable contains two independent components: the output format specification (<literal>ISO</>, <literal>Postgres</>, <literal>SQL</>, or <literal>German</>) and the input/output specification for year/month/day ordering (<literal>DMY</>, <literal>MDY</>, or <literal>YMD</>). These can be set separately or together. The keywords <literal>Euro</> and <literal>European</> are synonyms for <literal>DMY</>; the keywords <literal>US</>, <literal>NonEuro</>, and <literal>NonEuropean</> are synonyms for <literal>MDY</>. See <xref linkend="datatype-datetime"> for more information. The default is <literal>ISO, MDY</>. </para> </listitem> </varlistentry> <varlistentry id="guc-timezone" xreflabel="timezone"> <term><varname>timezone</varname> (<type>string</type>)</term> <indexterm> <primary><varname>timezone</> configuration parameter</primary> </indexterm> <indexterm><primary>time zone</></> <listitem> <para> Sets the time zone for displaying and interpreting time stamps. The default is 'unknown', which means to use whatever the system environment specifies as the time zone. See <xref linkend="datatype-datetime"> for more information. </para> </listitem> </varlistentry> <varlistentry id="guc-australian-timezones" xreflabel="australian_timezones"> <term><varname>australian_timezones</varname> (<type>boolean</type>)</term> <indexterm> <primary><varname>australian_timezones</> configuration parameter</primary> </indexterm> <indexterm><primary>time zone</><secondary>Australian</></> <listitem> <para> If set to true, <literal>ACST</literal>, <literal>CST</literal>, <literal>EST</literal>, and <literal>SAT</literal> are interpreted as Australian time zones rather than as North/South American time zones and Saturday. The default is false. </para> </listitem> </varlistentry> <varlistentry id="guc-extra-float-digits" xreflabel="extra_float_digits"> <indexterm> <primary>significant digits</primary> </indexterm> <indexterm> <primary>floating-point</primary> <secondary>display</secondary> </indexterm> <indexterm> <primary><varname>extra_float_digits</> configuration parameter</primary> </indexterm> <term><varname>extra_float_digits</varname> (<type>integer</type>)</term> <listitem> <para> This parameter adjusts the number of digits displayed for floating-point values, including <type>float4</>, <type>float8</>, and geometric data types. The parameter value is added to the standard number of digits (<literal>FLT_DIG</> or <literal>DBL_DIG</> as appropriate). The value can be set as high as 2, to include partially-significant digits; this is especially useful for dumping float data that needs to be restored exactly. Or it can be set negative to suppress unwanted digits. </para> </listitem> </varlistentry> <varlistentry id="guc-client-encoding" xreflabel="client_encoding"> <term><varname>client_encoding</varname> (<type>string</type>)</term> <indexterm> <primary><varname>client_encoding</> configuration parameter</primary> </indexterm> <indexterm><primary>character set</></> <listitem> <para> Sets the client-side encoding (character set). The default is to use the database encoding. </para> </listitem> </varlistentry> <varlistentry id="guc-lc-messages" xreflabel="lc_messages"> <term><varname>lc_messages</varname> (<type>string</type>)</term> <indexterm> <primary><varname>lc_messages</> configuration parameter</primary> </indexterm> <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 id="guc-lc-monetary" xreflabel="lc_monetary"> <term><varname>lc_monetary</varname> (<type>string</type>)</term> <indexterm> <primary><varname>lc_monetary</> configuration parameter</primary> </indexterm> <listitem> <para> Sets the locale to use for formatting monetary amounts, 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 id="guc-lc-numeric" xreflabel="lc_numeric"> <term><varname>lc_numeric</varname> (<type>string</type>)</term> <indexterm> <primary><varname>lc_numeric</> configuration parameter</primary> </indexterm> <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 id="guc-lc-time" xreflabel="lc_time"> <term><varname>lc_time</varname> (<type>string</type>)</term> <indexterm> <primary><varname>lc_time</> configuration parameter</primary> </indexterm> <listitem> <para> Sets the locale to use for formatting date and time values. (Currently, this setting does nothing, but it may in the future.) 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> </variablelist> </sect3> <sect3 id="runtime-config-client-other"> <title>Other Defaults</title> <variablelist> <varlistentry id="guc-explain-pretty-print" xreflabel="explain_pretty_print"> <term><varname>explain_pretty_print</varname> (<type>boolean</type>)</term> <indexterm> <primary><varname>explain_pretty_print</> configuration parameter</primary> </indexterm> <listitem> <para> Determines whether <command>EXPLAIN VERBOSE</> uses the indented or non-indented format for displaying detailed query-tree dumps. The default is on. </para> </listitem> </varlistentry> <varlistentry id="guc-dynamic-library-path" xreflabel="dynamic_library_path"> <term><varname>dynamic_library_path</varname> (<type>string</type>)</term> <indexterm> <primary><varname>dynamic_library_path</> configuration parameter</primary> </indexterm> <indexterm><primary>dynamic loading</></> <listitem> <para> If a dynamically loadable module needs to be opened and the file name specified in the <command>CREATE FUNCTION</command> or <command>LOAD</command> command does not have a directory component (i.e. the name does not contain a slash), the system will search this path for the required file. </para> <para> The value for <varname>dynamic_library_path</varname> has to be a list of absolute directory paths separated by colons (or semi-colons on Windows). If a list element starts with the special string <literal>$libdir</literal>, the compiled-in <productname>PostgreSQL</productname> package library directory is substituted for <literal>$libdir</literal>. This is where the modules provided by the standard <productname>PostgreSQL</productname> distribution are installed. (Use <literal>pg_config --pkglibdir</literal> to find out the name of this directory.) For example: <programlisting> dynamic_library_path = '/usr/local/lib/postgresql:/home/my_project/lib:$libdir' </programlisting> or, in a Windows environment: <programlisting> dynamic_library_path = 'C:\tools\postgresql;H:\my_project\lib;$libdir' </programlisting> </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> </variablelist> </sect3> </sect2> <sect2 id="runtime-config-locks"> <title>Lock Management</title> <variablelist> <varlistentry id="guc-deadlock-timeout" xreflabel="deadlock_timeout"> <indexterm> <primary>deadlock</primary> <secondary>timeout during</secondary> </indexterm> <indexterm> <primary>timeout</primary> <secondary>deadlock</secondary> </indexterm> <indexterm> <primary><varname>deadlock_timeout</> configuration parameter</primary> </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 the 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 a lock will be released before the waiter decides to check for deadlock. </para> </listitem> </varlistentry> <varlistentry id="guc-max-locks-per-transaction" xreflabel="max_locks_per_transaction"> <term><varname>max_locks_per_transaction</varname> (<type>integer</type>)</term> <indexterm> <primary><varname>max_locks_per_transaction</> configuration parameter</primary> </indexterm> <listitem> <para> The shared lock table is sized on the assumption that at most <varname>max_locks_per_transaction</varname> * <varname>max_connections</varname> distinct objects will need to be locked at any one time. (Thus, this parameter's name may be confusing: it is not a hard limit on the number of locks taken by any one transaction, but rather a maximum average value.) The default, 64, 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> </variablelist> </sect2> <sect2 id="runtime-config-compatible"> <title>Version and Platform Compatibility</title> <sect3 id="runtime-config-compatible-version"> <title>Previous PostgreSQL Versions</title> <variablelist> <varlistentry id="guc-add-missing-from" xreflabel="add_missing_from"> <term><varname>add_missing_from</varname> (<type>boolean</type>)</term> <indexterm><primary>FROM</><secondary>missing</></> <indexterm> <primary><varname>add_missing_from</> configuration parameter</primary> </indexterm> <listitem> <para> When <literal>true</>, tables that are referenced by a query will be automatically added to the <literal>FROM</> clause if not already present. The default is <literal>true</> for compatibility with previous releases of <productname>PostgreSQL</>. However, this behavior is not SQL-standard, and many people dislike it because it can mask mistakes (such as referencing a table where you should have referenced its alias). Set to <literal>false</> for the SQL-standard behavior of rejecting references to tables that are not listed in <literal>FROM</>. </para> </listitem> </varlistentry> <varlistentry id="guc-regex-flavor" xreflabel="regex_flavor"> <term><varname>regex_flavor</varname> (<type>string</type>)</term> <indexterm><primary>regular expressions</></> <indexterm> <primary><varname>regex_flavor</> configuration parameter</primary> </indexterm> <listitem> <para> The regular expression <quote>flavor</> can be set to <literal>advanced</>, <literal>extended</>, or <literal>basic</>. The default is <literal>advanced</>. The <literal>extended</> setting may be useful for exact backwards compatibility with pre-7.4 releases of <productname>PostgreSQL</>. See <xref linkend="posix-syntax-details"> for details. </para> </listitem> </varlistentry> <varlistentry id="guc-sql-inheritance" xreflabel="sql_inheritance"> <term><varname>sql_inheritance</varname> (<type>boolean</type>)</term> <indexterm> <primary><varname>sql_inheritance</> configuration parameter</primary> </indexterm> <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> key word to exclude subtables. See <xref linkend="ddl-inherit"> for more information about inheritance. </para> </listitem> </varlistentry> <varlistentry id="guc-default-with-oids" xreflabel="default_with_oids"> <term><varname>default_with_oids</varname> (<type>boolean</type>)</term> <indexterm> <primary><varname>default_with_oids</> configuration parameter</primary> </indexterm> <listitem> <para> This controls whether <command>CREATE TABLE</command> and <command>CREATE TABLE AS</command> include an OID column in newly-created tables, if neither <literal>WITH OIDS</literal> nor <literal>WITHOUT OIDS</literal> is specified. It also determines whether OIDs will be included in tables created by <command>SELECT INTO</command>. In <productname>PostgreSQL</productname> &version; <varname>default_with_oids</varname> defaults to true. This is also the behavior of previous versions of <productname>PostgreSQL</productname>. However, assuming that tables will contain OIDs by default is not encouraged. This option will probably default to false in a future release of <productname>PostgreSQL</productname>. </para> <para> To ease compatibility with applications that make use of OIDs, this option should left enabled. To ease compatibility with future versions of <productname>PostgreSQL</productname>, this option should be disabled, and applications that require OIDs on certain tables should explicitly specify <literal>WITH OIDS</literal> when those tables are created. </para> </listitem> </varlistentry> </variablelist> </sect3> <sect3 id="runtime-config-compatible-clients"> <title>Platform and Client Compatibility</title> <variablelist> <varlistentry id="guc-transform-null-equals" xreflabel="transform_null_equals"> <term><varname>transform_null_equals</varname> (<type>boolean</type>)</term> <indexterm><primary>IS NULL</></> <indexterm> <primary><varname>transform_null_equals</> configuration parameter</primary> </indexterm> <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 SQL-spec-compliant 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 null values, 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 the null value (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 values, so this option is not on by default. </para> <para> Note that this option only affects the exact form <literal>= NULL</>, 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 <xref linkend="functions-comparison"> for related information. </para> </listitem> </varlistentry> </variablelist> </sect3> </sect2> <sect2 id="runtime-config-preset"> <title>Preset Options</title> <para> The following <quote>parameters</> are read-only, and are determined when <productname>PostgreSQL</productname> is compiled or when it is installed. As such, they have been excluded from the sample <filename>postgresql.conf</> file. These options report various aspects of <productname>PostgreSQL</productname> behavior that may be of interest to certain applications, particularly administrative front-ends. </para> <variablelist> <varlistentry id="guc-block-size" xreflabel="block_size"> <term><varname>block_size</varname> (<type>integer</type>)</term> <indexterm> <primary><varname>block_size</> configuration parameter</primary> </indexterm> <listitem> <para> Shows the size of a disk block. It is determined by the value of <literal>BLCKSZ</> when building the server. The default value is 8192 bytes. The meaning of some configuration variables (such as <xref linkend="guc-shared-buffers">) is influenced by <varname>block_size</varname>. See <xref linkend="runtime-config-resource"> for information. </para> </listitem> </varlistentry> <varlistentry id="guc-integer-datetimes" xreflabel="integer_datetimes"> <term><varname>integer_datetimes</varname> (<type>boolean</type>)</term> <indexterm> <primary><varname>integer_datetimes</> configuration parameter</primary> </indexterm> <listitem> <para> Shows whether <productname>PostgreSQL</productname> was built with support for 64-bit-integer dates and times. It is set by configuring with <literal>--enable-integer-datetimes</literal> when building <productname>PostgreSQL</productname>. The default value is <literal>off</literal>. </para> </listitem> </varlistentry> <varlistentry id="guc-lc-collate" xreflabel="lc_collate"> <term><varname>lc_collate</varname> (<type>string</type>)</term> <indexterm> <primary><varname>lc_collate</> configuration parameter</primary> </indexterm> <listitem> <para> Shows the locale in which sorting of textual data is done. See <xref linkend="locale"> for more information. The value is determined when the database cluster is initialized. </para> </listitem> </varlistentry> <varlistentry id="guc-lc-ctype" xreflabel="lc_ctype"> <term><varname>lc_ctype</varname> (<type>string</type>)</term> <indexterm> <primary><varname>lc_ctype</> configuration parameter</primary> </indexterm> <listitem> <para> Shows the locale that determines character classifications. See <xref linkend="locale"> for more information. The value is determined when the database cluster is initialized. Ordinarily this will be the same as <varname>lc_collate</varname>, but for special applications it might be set differently. </para> </listitem> </varlistentry> <varlistentry id="guc-max-function-args" xreflabel="max_function_args"> <term><varname>max_function_args</varname> (<type>integer</type>)</term> <indexterm> <primary><varname>max_function_args</> configuration parameter</primary> </indexterm> <listitem> <para> Shows the maximum number of function arguments. It is determined by the value of <literal>FUNC_MAX_ARGS</> when building the server. The default value is 32. </para> </listitem> </varlistentry> <varlistentry id="guc-max-identifier-length" xreflabel="max_identifier_length"> <term><varname>max_identifier_length</varname> (<type>integer</type>)</term> <indexterm> <primary><varname>max_identifier_length</> configuration parameter</primary> </indexterm> <listitem> <para> Shows the maximum identifier length. It is determined as one less than the value of <literal>NAMEDATALEN</> when building the server. The default value of <literal>NAMEDATALEN</> is 64; therefore the default <varname>max_identifier_length</varname> is 63. </para> </listitem> </varlistentry> <varlistentry id="guc-max-index-keys" xreflabel="max_index_keys"> <term><varname>max_index_keys</varname> (<type>integer</type>)</term> <indexterm> <primary><varname>max_index_keys</> configuration parameter</primary> </indexterm> <listitem> <para> Shows the maximum number of index keys. It is determined by the value of <literal>INDEX_MAX_KEYS</> when building the server. The default value is 32. </para> </listitem> </varlistentry> <varlistentry id="guc-server-encoding" xreflabel="server_encoding"> <term><varname>server_encoding</varname> (<type>string</type>)</term> <indexterm> <primary><varname>server_encoding</> configuration parameter</primary> </indexterm> <indexterm><primary>character set</></> <listitem> <para> Shows the database encoding (character set). It is determined when the database is created. Ordinarily, clients need only be concerned with the value of <xref linkend="guc-client-encoding">. </para> </listitem> </varlistentry> <varlistentry id="guc-server-version" xreflabel="server_version"> <term><varname>server_version</varname> (<type>string</type>)</term> <indexterm> <primary><varname>server_version</> configuration parameter</primary> </indexterm> <listitem> <para> Shows the version number of the server. It is determined by the value of <literal>PG_VERSION</> when building the server. </para> </listitem> </varlistentry> </variablelist> </sect2> <sect2 id="runtime-config-custom"> <title>Customized Options</title> <para> This feature was designed to allow options not normally known to <productname>PostgreSQL</productname> to be added by add-on modules (such as procedural languages). This allows add-on modules to be configured in the standard ways. </para> <variablelist> <varlistentry id="guc-custom-variable-classes" xreflabel="custom_variable_classes"> <term><varname>custom_variable_classes</varname> (<type>string</type>)</term> <indexterm> <primary><varname>custom_variable_classes</> configuration parameter</primary> </indexterm> <listitem> <para> This variable specifies one or several class names to be used for custom variables, in the form of a comma-separated list. A custom variable is a variable not normally known to <productname>PostgreSQL</productname> proper but used by some add-on module. Such variables must have names consisting of a class name, a dot, and a variable name. <varname>custom_variable_classes</> specifies all the class names in use in a particular installation. This option can only be set at server start or in the <filename>postgresql.conf</filename> configuration file. </para> </listitem> </varlistentry> </variablelist> <para> The difficulty with setting custom variables in <filename>postgresql.conf</> is that the file must be read before add-on modules have been loaded, and so custom variables would ordinarily be rejected as unknown. When <varname>custom_variable_classes</> is set, the server will accept definitions of arbitrary variables within each specified class. These variables will be treated as placeholders and will have no function until the module that defines them is loaded. When a module for a specific class is loaded, it will add the proper variable definitions for its class name, convert any placeholder values according to those definitions, and issue warnings for any placeholders of its class that remain (which presumably would be misspelled configuration variables). </para> <para> Here is an example of what <filename>postgresql.conf</> might contain when using custom variables: <programlisting> custom_variable_classes = 'plr,pljava' plr.path = '/usr/lib/R' pljava.foo = 1 plruby.bar = true # generates error, unknown class name </programlisting> </para> </sect2> <sect2 id="runtime-config-developer"> <title>Developer Options</title> <para> The following options are intended for work on the <productname>PostgreSQL</productname> source, and in some cases to assist with recovery of severely damaged databases. There should be no reason to use them in a production database setup. As such, they have been excluded from the sample <filename>postgresql.conf</> file. Note that many of these options require special source compilation flags to work at all. </para> <variablelist> <varlistentry id="guc-debug-assertions" xreflabel="debug_assertions"> <term><varname>debug_assertions</varname> (<type>boolean</type>)</term> <indexterm> <primary><varname>debug_assertions</> configuration parameter</primary> </indexterm> <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 <symbol>USE_ASSERT_CHECKING</symbol> must be defined when <productname>PostgreSQL</productname> is built (accomplished by the <command>configure</command> option <option>--enable-cassert</option>). Note that <varname>debug_assertions</varname> defaults to on if <productname>PostgreSQL</productname> has been built with assertions enabled. </para> </listitem> </varlistentry> <varlistentry id="guc-pre-auth-delay" xreflabel="pre_auth_delay"> <term><varname>pre_auth_delay</varname> (<type>integer</type>)</term> <indexterm> <primary><varname>pre_auth_delay</> configuration parameter</primary> </indexterm> <listitem> <para> If nonzero, a delay of this many seconds occurs just after a new server process is forked, before it conducts the authentication process. This is intended to give an opportunity to attach to the server process with a debugger to trace down misbehavior in authentication. </para> </listitem> </varlistentry> <varlistentry id="guc-trace-notify" xreflabel="trace_notify"> <term><varname>trace_notify</varname> (<type>boolean</type>)</term> <indexterm> <primary><varname>trace_notify</> configuration parameter</primary> </indexterm> <listitem> <para> Generates a great amount of debugging output for the <command>LISTEN</command> and <command>NOTIFY</command> commands. <xref linkend="guc-client-min-messages"> or <xref linkend="guc-log-min-messages"> must be <literal>DEBUG1</literal> or lower to send this output to the client or server log, respectively. </para> </listitem> </varlistentry> <varlistentry> <term><varname>trace_locks</varname> (<type>boolean</type>)</term> <term><varname>trace_lwlocks</varname> (<type>boolean</type>)</term> <term><varname>trace_userlocks</varname> (<type>boolean</type>)</term> <term><varname>trace_lock_oidmin</varname> (<type>boolean</type>)</term> <term><varname>trace_lock_table</varname> (<type>boolean</type>)</term> <term><varname>debug_deadlocks</varname> (<type>boolean</type>)</term> <term><varname>log_btree_build_stats</varname> (<type>boolean</type>)</term> <listitem> <para> Various other code tracing and debugging options. </para> </listitem> </varlistentry> <varlistentry id="guc-wal-debug" xreflabel="wal_debug"> <term><varname>wal_debug</varname> (<type>boolean</type>)</term> <indexterm> <primary><varname>wal_debug</> configuration parameter</primary> </indexterm> <listitem> <para> If true, emit WAL-related debugging output. This option is only available if the <symbol>WAL_DEBUG</symbol> macro was defined when <productname>PostgreSQL</productname> was compiled. </para> </listitem> </varlistentry> <varlistentry id="guc-zero-damaged-pages" xreflabel="zero_damaged_pages"> <term><varname>zero_damaged_pages</varname> (<type>boolean</type>)</term> <indexterm> <primary><varname>zero_damaged_pages</> configuration parameter</primary> </indexterm> <listitem> <para> Detection of a damaged page header normally causes <productname>PostgreSQL</> to report an error, aborting the current command. Setting <varname>zero_damaged_pages</> to true causes the system to instead report a warning, zero out the damaged page, and continue processing. This behavior <emphasis>will destroy data</>, namely all the rows on the damaged page. But it allows you to get past the error and retrieve rows from any undamaged pages that may be present in the table. So it is useful for recovering data if corruption has occurred due to hardware or software error. You should generally not set this true until you have given up hope of recovering data from the damaged page(s) of a table. The default setting is off, and it can only be changed by a superuser. </para> </listitem> </varlistentry> </variablelist> </sect2> <sect2 id="runtime-config-short"> <title>Short Options</title> <para> For convenience there are also single letter command-line option switches available for some parameters. They are described in <xref linkend="runtime-config-short-table">. </para> <table id="runtime-config-short-table"> <title>Short option key</title> <tgroup cols="2"> <thead> <row> <entry>Short option</entry> <entry>Equivalent</entry> </row> </thead> <tbody> <row> <entry><option>-B <replaceable>x</replaceable></option></entry> <entry><literal>shared_buffers = <replaceable>x</replaceable></></entry> </row> <row> <entry><option>-d <replaceable>x</replaceable></option></entry> <entry><literal>log_min_messages = DEBUG<replaceable>x</replaceable></></entry> </row> <row> <entry><option>-F</option></entry> <entry><literal>fsync = off</></entry> </row> <row> <entry><option>-h <replaceable>x</replaceable></option></entry> <entry><literal>listen_addresses = <replaceable>x</replaceable></></entry> </row> <row> <entry><option>-i</option></entry> <entry><literal>listen_addresses = '*'</></entry> </row> <row> <entry><option>-k <replaceable>x</replaceable></option></entry> <entry><literal>unix_socket_directory = <replaceable>x</replaceable></></entry> </row> <row> <entry><option>-l</option></entry> <entry><literal>ssl = on</></entry> </row> <row> <entry><option>-N <replaceable>x</replaceable></option></entry> <entry><literal>max_connections = <replaceable>x</replaceable></></entry> </row> <row> <entry><option>-p <replaceable>x</replaceable></option></entry> <entry><literal>port = <replaceable>x</replaceable></></entry> </row> <row> <entry> <option>-fi</option>, <option>-fh</option>, <option>-fm</option>, <option>-fn</option>, <option>-fs</option>, <option>-ft</option><footnote id="fn.runtime-config-short"> <para> For historical reasons, these options must be passed to the individual server process via the <option>-o</option> <command>postmaster</command> 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> </footnote> </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> </row> <row> <entry><option>-s</option><footnoteref linkend="fn.runtime-config-short"></entry> <entry><literal>log_statement_stats = on</></entry> </row> <row> <entry><option>-S <replaceable>x</replaceable></option><footnoteref linkend="fn.runtime-config-short"> </entry> <entry><literal>work_mem = <replaceable>x</replaceable></></entry> </row> <row> <entry><option>-tpa</option>, <option>-tpl</option>, <option>-te</option><footnoteref linkend="fn.runtime-config-short"></entry> <entry><literal>log_parser_stats = on</>, <literal>log_planner_stats = on</>, <literal>log_executor_stats = on</></entry> </row> </tbody> </tgroup> </table> </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 server 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 server 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>250 kB + 8.2 kB * <xref linkend="guc-shared-buffers"> + 14.2 kB * <xref linkend="guc-max-connections"> up to 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>at least <literal>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> plus room for other applications</> </row> <row> <entry><varname>SEMMSL</></> <entry>Maximum number of semaphores per set</> <entry>at least 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>at least 1000 (The default is often 32767, don't change unless forced 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 likely 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 as suggested in <xref linkend="sysvipc-parameters">. Any error message you might get will contain the size of the failed allocation request. </para> <para> Some systems also have a limit on the total amount of shared memory in the system (<varname>SHMALL</>). Make sure this is large enough for <productname>PostgreSQL</> plus any other applications that are using shared memory segments. (Caution: <varname>SHMALL</> is measured in pages rather than bytes on many systems.) </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</>) are unlikely to cause a problem unless your system has them set to zero. </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 <varname>max_connections</> 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 <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> <variablelist> <varlistentry> <term><systemitem class="osname">BSD/OS</></term> <indexterm><primary>BSD/OS</><secondary>IPC configuration</></> <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 amount of shared memory supported by your system, add something like the following to your kernel configuration file: <programlisting> options "SHMALL=8192" options "SHMMAX=\(SHMALL*PAGE_SIZE\)" </programlisting> <varname>SHMALL</> is measured in 4KB pages, so a value of 1024 represents 4 MB of shared memory. Therefore the above increases the maximum shared memory area to 32 MB. For those running 4.3 or later, you will probably also need to increase <varname>KERNEL_VIRTUAL_MB</> above the default <literal>248</>. Once all changes have been made, recompile the kernel, and reboot. </para> </formalpara> <para> For those running 4.0 and earlier releases, use <command>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 <command>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 will probably want to increase the number of semaphores as well; the default system total of 60 will only allow about 50 <productname>PostgreSQL</productname> connections. Set the values you want in your kernel configuration file, e.g.: <programlisting> options "SEMMNI=40" options "SEMMNS=240" </programlisting> </para> </formalpara> </listitem> </varlistentry> <varlistentry> <term><systemitem class="osname">FreeBSD</></term> <indexterm><primary>FreeBSD</><secondary>IPC configuration</></> <listitem> <para> The default settings are only suitable for small installations (for example, default <varname>SHMMAX</varname> is 32 MB). Changes can be made via the <command>sysctl</command> or <command>loader</command> interfaces. The following parameters can be set using <command>sysctl</command>: <screen> <prompt>$</prompt> <userinput>sysctl -w kern.ipc.shmall=32768</userinput> <prompt>$</prompt> <userinput>sysctl -w kern.ipc.shmmax=134217728</userinput> <prompt>$</prompt> <userinput>sysctl -w kern.ipc.semmap=256</userinput> </screen> To have these settings persist over reboots, modify <filename>/etc/sysctl.conf</filename>. </para> <para> The remaining sempahore settings are read-only as far as <command>sysctl</command> is concerned, but can be changed before boot using the <command>loader</command> prompt: <screen> <prompt>(loader)</prompt> <userinput>set kern.ipc.semmni=256</userinput> <prompt>(loader)</prompt> <userinput>set kern.ipc.semmns=512</userinput> <prompt>(loader)</prompt> <userinput>set kern.ipc.semmnu=256</userinput> </screen> Similarly these can be saved between reboots in <filename>/boot/loader.conf</filename>. </para> <para> You might also want to configure your kernel to lock shared memory into RAM and prevent it from being paged out to swap. This can be accomplished using the <command>sysctl</command> setting <literal>kern.ipc.shm_use_phys</literal>. </para> <para> <systemitem class="osname">FreeBSD</> versions before 4.0 work like <systemitem class="osname">NetBSD</> and <systemitem class="osname"> OpenBSD</> (see below), except that the configuration file uses the keyword "options" instead of "option". </para> </listitem> </varlistentry> <varlistentry> <term><systemitem class="osname">NetBSD</></term> <term><systemitem class="osname">OpenBSD</></term> <indexterm><primary>NetBSD</><secondary>IPC configuration</></> <indexterm><primary>OpenBSD</><secondary>IPC configuration</></> <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> option SYSVSHM option SHMMAXPGS=4096 option SHMSEG=256 option SYSVSEM option SEMMNI=256 option SEMMNS=512 option SEMMNU=256 option SEMMAP=256 </programlisting> </para> <para> You might also want to configure your kernel to lock shared memory into RAM and prevent it from being paged out to swap. This can be accomplished using the <command>sysctl</command> setting <literal>kern.ipc.shm_use_phys</literal>. </para> </listitem> </varlistentry> <varlistentry> <term><systemitem class="osname">HP-UX</></term> <indexterm><primary>HP-UX</><secondary>IPC configuration</></> <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</><secondary>IPC configuration</></> <listitem> <para> The default settings are only suitable for small installations (the default max segment size is 32 MB). However the remaining defaults are quite generously sized, and usually do not require changes. The max segment size can be changed via the <command>sysctl</command> interface. For example, to allow 128 MB, and explicitly set the maximum total shared memory size to 2097152 pages (the default): <screen> <prompt>$</prompt> <userinput>sysctl -w kernel.shmmax=134217728</userinput> <prompt>$</prompt> <userinput>sysctl -w kernel.shmall=2097152</userinput> </screen> In addition these settings can be saved between reboots in <filename>/etc/sysctl.conf. </para> <para> Older distributions may not have the <command>sysctl</command> program, but equivalent changes can be made by manipulating the <filename>/proc</filename> filesystem: <screen> <prompt>$</prompt> <userinput>echo 134217728 >/proc/sys/kernel/shmmax</userinput> <prompt>$</prompt> <userinput>echo 2097152 >/proc/sys/kernel/shmall</userinput> </screen> </para> </listitem> </varlistentry> <varlistentry> <term><systemitem class="osname">MacOS X</></term> <indexterm><primary>MacOS X</><secondary>IPC configuration</></> <listitem> <para> In OS X 10.2 and earlier, edit the file <filename>/System/Library/StartupItems/SystemTuning/SystemTuning</> and change the values in the following commands: <programlisting> sysctl -w kern.sysv.shmmax sysctl -w kern.sysv.shmmin sysctl -w kern.sysv.shmmni sysctl -w kern.sysv.shmseg sysctl -w kern.sysv.shmall </programlisting> In OS X 10.3, these commands have been moved to <filename>/etc/rc</> and must be edited there. You'll need to reboot to make changes take effect. Note that <filename>/etc/rc</> is usually overwritten by OS X updates (such as 10.3.6 to 10.3.7) so you should expect to have to redo your editing after each update. </para> <para> <varname>SHMALL</> is measured in 4KB pages on this platform. </para> </listitem> </varlistentry> <varlistentry> <term><systemitem class="osname">SCO OpenServer</></term> <indexterm><primary>SCO OpenServer</><secondary>IPC configuration</></> <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 to the directory <filename>/etc/conf/cf.d</>. To display the current value of <varname>SHMMAX</>, 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">AIX</></term> <indexterm><primary>AIX</><secondary>IPC configuration</></> <listitem> <para> At least as of version 5.1, it should not be necessary to do any special configuration for such parameters as <varname>SHMMAX</varname>, as it appears this is configured to allow all memory to be used as shared memory. That is the sort of configuration commonly used for other databases such as <application>DB/2</application>.</para> <para> It may, however, be necessary to modify the global <command>ulimit</command> information in <filename>/etc/security/limits</filename>, as the default hard limits for file sizes (<varname>fsize</varname>) and numbers of files (<varname>nofiles</varname>) may be too low. </para> </listitem> </varlistentry> <varlistentry> <term><systemitem class="osname">Solaris</></term> <indexterm><primary>Solaris</><secondary>IPC configuration</></> <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://sunsite.uakom.sk/sunworldonline/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</><secondary>IPC configuration</></> <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. 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> </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 the operating system documentation 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 you do not want to alter the system-wide limit, you can set <productname>PostgreSQL</>'s <xref linkend="guc-max-files-per-process"> configuration parameter to limit the consumption of open files. </para> </sect2> <sect2> <title>Linux Memory Overcommit</title> <para> In Linux 2.4 and later, the default virtual memory behavior is not optimal for <productname>PostgreSQL</productname>. Because of the way that the kernel implements memory overcommit, the kernel may terminate the <productname>PostgreSQL</productname> server (the <filename>postmaster</filename> process) if the memory demands of another process cause the system to run out of virtual memory. </para> <para> If this happens, you will see a kernel message that looks like this (consult your system documentation and configuration on where to look for such a message): <programlisting> Out of Memory: Killed process 12345 (postmaster). </programlisting> This indicates that the <filename>postmaster</filename> process has been terminated due to memory pressure. Although existing database connections will continue to function normally, no new connections will be accepted. To recover, <productname>PostgreSQL</productname> will need to be restarted. </para> <para> One way to avoid this problem is to run <productname>PostgreSQL</productname> on a machine where you can be sure that other processes will not run the machine out of memory. </para> <para> On Linux 2.6 and later, a better solution is to modify the kernel's behavior so that it will not <quote>overcommit</> memory. This is done by selecting strict overcommit mode via <command>sysctl</command>: <programlisting> sysctl -w vm.overcommit_memory=2 </programlisting> or placing an equivalent entry in <filename>/etc/sysctl.conf</>. You may also wish to modify the related setting <literal>vm.overcommit_ratio</>. For details see the kernel documentation file <filename>Documentation/vm/overcommit-accounting</>. </para> <para> Some vendors' Linux 2.4 kernels are reported to have early versions of the 2.6 overcommit <command>sysctl</command> parameter. However, setting <literal>vm.overcommit_memory</> to 2 on a kernel that does not have the relevant code will make things worse not better. It is recommended that you inspect the actual kernel source code (see the function <function>vm_enough_memory</> in the file <filename>mm/mmap.c</>) to verify what is supported in your copy before you try this in a 2.4 installation. The presence of the <filename>overcommit-accounting</> documentation file should <emphasis>not</> be taken as evidence that the feature is there. If in any doubt, consult a kernel expert or your kernel vendor. </para> </sect2> </sect1> <sect1 id="postmaster-shutdown"> <title>Shutting Down the Server</title> <indexterm zone="postmaster-shutdown"> <primary>shutdown</> </indexterm> <para> There are several ways to shut down the database server. You control the type of shutdown by sending different signals to the <command>postmaster</command> process. <variablelist> <varlistentry> <term><systemitem>SIGTERM</systemitem><indexterm><primary>SIGTERM</></></term> <listitem> <para> After receiving <systemitem>SIGTERM</systemitem>, the server disallows new connections, but lets existing sessions end their work normally. It shuts down only after all of the sessions terminate normally. This is the <firstterm>Smart Shutdown</firstterm>. </para> </listitem> </varlistentry> <varlistentry> <term><systemitem>SIGINT</systemitem><indexterm><primary>SIGINT</></></term> <listitem> <para> The server disallows new connections and sends all existing server processes <systemitem>SIGTERM</systemitem>, which will cause them to abort their current transactions and exit promptly. It then waits for the server processes to exit and finally shuts down. This is the <firstterm>Fast Shutdown</firstterm>. </para> </listitem> </varlistentry> <varlistentry> <term><systemitem>SIGQUIT</systemitem><indexterm><primary>SIGQUIT</></></term> <listitem> <para> This is the <firstterm>Immediate Shutdown</firstterm>, which will cause the <command>postmaster</command> process to send a <systemitem>SIGQUIT</systemitem> to all child processes and exit immediately, without properly shutting itself down. The child processes 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> </para> <para> The <xref linkend="app-pg-ctl"> program provides a convenient interface for sending these signals to shut down the server. </para> <para> Alternatively, you can send the signal directly using <command>kill</>. The <acronym>PID</> of the <command>postmaster</command> process can be found using the <command>ps</command> program, or from the file <filename>postmaster.pid</filename> in the data directory. For example, to do a fast shutdown: <screen> $ <userinput>kill -INT `head -1 /usr/local/pgsql/data/postmaster.pid`</userinput> </screen> </para> <important> <para> It is best not to use <systemitem>SIGKILL</systemitem> to shut down the server. Doing so will prevent the server from releasing shared memory and semaphores, which may then have to be done manually before a new server can be started. Furthermore, <systemitem>SIGKILL</systemitem> kills the <command>postmaster</command> process without letting it relay the signal to its subprocesses, so it will be necessary to kill the individual subprocesses by hand as well. </para> </important> </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 that <productname>OpenSSL</productname> is installed on both client and server systems and that support in <productname>PostgreSQL</> is enabled at build time (see <xref linkend="installation">). </para> <para> With <acronym>SSL</> support compiled in, the <productname>PostgreSQL</> server can be started with <acronym>SSL</> enabled by setting the parameter <xref linkend="guc-ssl"> to <literal>on</> in <filename>postgresql.conf</>. When starting in <acronym>SSL</> mode, the server will look for the files <filename>server.key</> and <filename>server.crt</> in the data directory, which must contain the server private key and certificate, respectively. These files must be set up correctly before an <acronym>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 <acronym>SSL</> connections on the same TCP port, and will negotiate with any connecting client on whether to use <acronym>SSL</>. By default, this is at the client's option; see <xref linkend="auth-pg-hba-conf"> about how to set up the server to require use of <acronym>SSL</> for some or all connections. </para> <para> For details on how to create your server private key and certificate, refer to the <productname>OpenSSL</> documentation. A self-signed certificate can be used for testing, but a certificate signed by a certificate authority (<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 server.req </programlisting> Fill out the information that <command>openssl</> asks for. Make sure that you enter the local host name as <quote>Common Name</>; the challenge password can be left blank. The program will generate a key that is passphrase protected; it will not accept a passphrase 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 server.key rm privkey.pem </programlisting> Enter the old passphrase to unlock the existing key. Now do <programlisting> openssl req -x509 -in server.req -text -key server.key -out server.crt chmod og-rwx server.key </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> <para> If verification of client certificates is required, place the certificates of the <acronym>CA</acronym>(s) you wish to check for in the file <filename>root.crt</filename> in the data directory. When present, a client certificate will be requested from the client during SSL connection startup, and it must have been signed by one of the certificates present in <filename>root.crt</filename>. </para> <para> When the <filename>root.crt</filename> file is not present, client certificates will not be requested or checked. In this mode, SSL provides communication security but not authentication. </para> <para> The files <filename>server.key</>, <filename>server.crt</>, and <filename>root.crt</filename> are only examined during server start; so you must restart the server to make changes in them take effect. </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> <para> One can use <application>SSH</application> to encrypt the network connection between clients and a <productname>PostgreSQL</productname> server. Done properly, this provides an adequately secure network connection, even for non-SSL-capable clients. </para> <para> First make sure that an <application>SSH</application> server is running properly on the same machine as the <productname>PostgreSQL</productname> server 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> ssh -L 3333:foo.com:5432 joe@foo.com </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 IP address 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 configured for connections from this user and host. Note that the server will not think the connection is SSL-encrypted, since in fact it is not encrypted between the <application>SSH</application> server and the <productname>PostgreSQL</productname> server. This should not pose any extra security risk as long as they are on the same machine. </para> <para> In order for the tunnel setup to succeed you must be allowed to connect via <command>ssh</command> as <literal>joe@foo.com</literal>, just as if you had attempted to use <command>ssh</command> to set up a terminal session. </para> <tip> <para> Several other applications 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: -->