
This patch has two distinct purposes: to report multiple problems in postgresql.conf rather than always bailing out after the first one, and to change the policy for whether changes are applied when there are unrelated errors in postgresql.conf. Formerly the policy was to apply no changes if any errors could be detected, but that had a significant consistency problem, because in some cases specific values might be seen as valid by some processes but invalid by others. This meant that the latter processes would fail to adopt changes in other parameters even though the former processes had done so. The new policy is that during SIGHUP, the file is rejected as a whole if there are any errors in the "name = value" syntax, or if any lines attempt to set nonexistent built-in parameters, or if any lines attempt to set custom parameters whose prefix is not listed in (the new value of) custom_variable_classes. These tests should always give the same results in all processes, and provide what seems a reasonably robust defense against loading values from badly corrupted config files. If these tests pass, all processes will apply all settings that they individually see as good, ignoring (but logging) any they don't. In addition, the postmaster does not abandon reading a configuration file after the first syntax error, but continues to read the file and report syntax errors (up to a maximum of 100 syntax errors per file). The postmaster will still refuse to start up if the configuration file contains any errors at startup time, but these changes allow multiple errors to be detected and reported before quitting. Alexey Klyukin, reviewed by Andy Colson and av (Alexander ?) with some additional hacking by Tom Lane
6462 lines
270 KiB
Plaintext
6462 lines
270 KiB
Plaintext
<!-- doc/src/sgml/config.sgml -->
|
|
|
|
<chapter id="runtime-config">
|
|
<title>Server Configuration</title>
|
|
|
|
<indexterm>
|
|
<primary>configuration</primary>
|
|
<secondary>of the server</secondary>
|
|
</indexterm>
|
|
|
|
<para>
|
|
There are many configuration parameters that affect the behavior of
|
|
the database system. In the first section of this chapter, we
|
|
describe how to set configuration parameters. The subsequent sections
|
|
discuss each parameter in detail.
|
|
</para>
|
|
|
|
<sect1 id="config-setting">
|
|
<title>Setting Parameters</title>
|
|
|
|
<para>
|
|
All parameter names are case-insensitive. Every parameter takes a
|
|
value of one of five types: Boolean, integer, floating point,
|
|
string or enum. Boolean values can 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>
|
|
Some settings specify a memory or time value. Each of these has an
|
|
implicit unit, which is either kilobytes, blocks (typically eight
|
|
kilobytes), milliseconds, seconds, or minutes. Default units can be
|
|
found by referencing <structname>pg_settings</>.<structfield>unit</>.
|
|
For convenience,
|
|
a different unit can also be specified explicitly. Valid memory units
|
|
are <literal>kB</literal> (kilobytes), <literal>MB</literal>
|
|
(megabytes), and <literal>GB</literal> (gigabytes); valid time units
|
|
are <literal>ms</literal> (milliseconds), <literal>s</literal>
|
|
(seconds), <literal>min</literal> (minutes), <literal>h</literal>
|
|
(hours), and <literal>d</literal> (days). Note that the multiplier
|
|
for memory units is 1024, not 1000.
|
|
</para>
|
|
|
|
<para>
|
|
Parameters of type <quote>enum</> are specified in the same way as string
|
|
parameters, but are restricted to a limited set of values. The allowed
|
|
values can be found
|
|
from <structname>pg_settings</>.<structfield>enumvals</>.
|
|
Enum parameter values are case-insensitive.
|
|
</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. (A default copy is
|
|
installed there when the database cluster directory is
|
|
initialized.) 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'
|
|
shared_buffers = 128MB
|
|
</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>) designate the rest of the
|
|
line as a comment. Parameter values that are not simple identifiers or
|
|
numbers must be single-quoted. To embed a single quote in a parameter
|
|
value, write either two quotes (preferred) or backslash-quote.
|
|
</para>
|
|
|
|
<para>
|
|
<indexterm>
|
|
<primary><literal>include</></primary>
|
|
<secondary>in configuration file</secondary>
|
|
</indexterm>
|
|
In addition to parameter settings, the <filename>postgresql.conf</>
|
|
file can contain <firstterm>include directives</>, which specify
|
|
another file to read and process as if it were inserted into the
|
|
configuration file at this point. Include directives simply look like:
|
|
<programlisting>
|
|
include 'filename'
|
|
</programlisting>
|
|
If the file name is not an absolute path, it is taken as relative to
|
|
the directory containing the referencing configuration file.
|
|
Inclusions can be nested.
|
|
</para>
|
|
|
|
<para>
|
|
<indexterm>
|
|
<primary>SIGHUP</primary>
|
|
</indexterm>
|
|
The configuration file is reread whenever the main server process receives a
|
|
<systemitem>SIGHUP</> signal (which is most easily sent by means
|
|
of <literal>pg_ctl reload</>). The main server process
|
|
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. Invalid parameter settings in the
|
|
configuration file are likewise ignored (but logged) during
|
|
<systemitem>SIGHUP</> processing.
|
|
</para>
|
|
|
|
<para>
|
|
A second way to set these configuration parameters is to give them
|
|
as a command-line option to the <command>postgres</command> command, such as:
|
|
<programlisting>
|
|
postgres -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 might 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 parameter 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-alterrole">
|
|
and <xref linkend="sql-alterdatabase">,
|
|
respectively, are used to configure these settings. Per-database
|
|
settings override anything received from the
|
|
<command>postgres</command> command-line or the configuration
|
|
file, and in turn are overridden by per-user settings; both are
|
|
overridden by per-session settings.
|
|
</para>
|
|
|
|
<para>
|
|
Some parameters can be changed in individual <acronym>SQL</acronym>
|
|
sessions with the <xref linkend="SQL-SET">
|
|
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 be changed without restarting the entire
|
|
<productname>PostgreSQL</productname> server. Also,
|
|
some <command>SET</command> or <command>ALTER</> parameter modifications
|
|
require superuser permission.
|
|
</para>
|
|
|
|
<para>
|
|
The <xref linkend="SQL-SHOW">
|
|
command allows inspection of the current values of all parameters.
|
|
</para>
|
|
|
|
<para>
|
|
The virtual table <structname>pg_settings</structname> also allows
|
|
displaying and updating session run-time parameters; see <xref
|
|
linkend="view-pg-settings"> for details and a description of the
|
|
different variable types and when they can be changed.
|
|
<structname>pg_settings</structname> 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. It also contains more information about
|
|
what values are allowed for the parameters.
|
|
</para>
|
|
</sect1>
|
|
|
|
<sect1 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 parameters described in this section 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 parameter 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 parameter can only be set on the <command>postgres</command> 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 parameter 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
|
|
<xref linkend="auth-username-maps"> user name mapping
|
|
(customarily called <filename>pg_ident.conf</>).
|
|
This parameter 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
|
|
server should create for use by server administration programs.
|
|
This parameter can only be set at server start.
|
|
</para>
|
|
</listitem>
|
|
</varlistentry>
|
|
</variablelist>
|
|
|
|
<para>
|
|
In a default installation, none of the above parameters 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 <command>postgres</command> <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</> parameter 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 parameters <varname>config_file</>,
|
|
<varname>hba_file</> and/or <varname>ident_file</>.
|
|
<varname>config_file</> can only be specified on the
|
|
<command>postgres</command> command line, but the others can be
|
|
set within the main configuration file. If all three parameters 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 parameters, a relative path will be interpreted
|
|
with respect to the directory in which <command>postgres</command>
|
|
is started.
|
|
</para>
|
|
</sect1>
|
|
|
|
<sect1 id="runtime-config-connection">
|
|
<title>Connections and Authentication</title>
|
|
|
|
<sect2 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. The entry
|
|
<literal>0.0.0.0</> allows listening for all IPv4 addresses and
|
|
<literal>::</> allows listening for all IPv6 addresses.
|
|
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 TCP/IP <quote>loopback</> connections to be
|
|
made. While client authentication (<xref
|
|
linkend="client-authentication">) allows fine-grained control
|
|
over who can access the server, <varname>listen_addresses</varname>
|
|
controls which interfaces accept connection attempts, which
|
|
can help prevent repeated malicious connection requests on
|
|
insecure network interfaces. 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 connections, but
|
|
might 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 might 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>
|
|
|
|
<para>
|
|
When running a standby server, you must set this parameter to the
|
|
same or higher value than on the master server. Otherwise, queries
|
|
will not be allowed in the standby server.
|
|
</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, and no
|
|
new replication connections will be accepted.
|
|
</para>
|
|
|
|
<para>
|
|
The default value is three connections. 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>
|
|
|
|
<para>
|
|
In addition to the socket file itself, which is named
|
|
<literal>.s.PGSQL.<replaceable>nnnn</></literal> where
|
|
<replaceable>nnnn</> is the server's port number, an ordinary file
|
|
named <literal>.s.PGSQL.<replaceable>nnnn</>.lock</literal> will be
|
|
created in the <varname>unix_socket_directory</> directory. Neither
|
|
file should ever be removed manually.
|
|
</para>
|
|
|
|
<para>
|
|
This parameter is irrelevant on Windows, which does not have
|
|
Unix-domain sockets.
|
|
</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 parameter
|
|
<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 of the server user. This parameter can only be set at
|
|
server start.
|
|
</para>
|
|
|
|
<para>
|
|
This parameter is irrelevant on Windows, which does not have
|
|
Unix-domain sockets.
|
|
</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 parameter value is expected to be a numeric mode
|
|
specified in the format 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, 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 parameter can only be set at server start.
|
|
</para>
|
|
|
|
<para>
|
|
This parameter is irrelevant on Windows, which does not have
|
|
Unix-domain sockets.
|
|
</para>
|
|
</listitem>
|
|
</varlistentry>
|
|
|
|
<varlistentry id="guc-bonjour" xreflabel="bonjour">
|
|
<term><varname>bonjour</varname> (<type>boolean</type>)</term>
|
|
<indexterm>
|
|
<primary><varname>bonjour</> configuration parameter</primary>
|
|
</indexterm>
|
|
<listitem>
|
|
<para>
|
|
Enables advertising the server's existence via
|
|
<productname>Bonjour</productname>. The default is off.
|
|
This parameter can only be set at server start.
|
|
</para>
|
|
</listitem>
|
|
</varlistentry>
|
|
|
|
<varlistentry id="guc-bonjour-name" xreflabel="bonjour_name">
|
|
<term><varname>bonjour_name</varname> (<type>string</type>)</term>
|
|
<indexterm>
|
|
<primary><varname>bonjour_name</> configuration parameter</primary>
|
|
</indexterm>
|
|
<listitem>
|
|
<para>
|
|
Specifies the <productname>Bonjour</productname> service
|
|
name. The computer name is used if this parameter is set to the
|
|
empty string <literal>''</> (which is the default). This parameter is
|
|
ignored if the server was not compiled with
|
|
<productname>Bonjour</productname> support.
|
|
This parameter can only be set at server start.
|
|
</para>
|
|
</listitem>
|
|
</varlistentry>
|
|
|
|
<varlistentry id="guc-tcp-keepalives-idle" xreflabel="tcp_keepalives_idle">
|
|
<term><varname>tcp_keepalives_idle</varname> (<type>integer</type>)</term>
|
|
<indexterm>
|
|
<primary><varname>tcp_keepalives_idle</> configuration parameter</primary>
|
|
</indexterm>
|
|
<listitem>
|
|
<para>
|
|
Specifies the number of seconds before sending a keepalive packet on
|
|
an otherwise idle connection. A value of 0 uses the system default.
|
|
This parameter is supported only on systems that support the
|
|
<symbol>TCP_KEEPIDLE</> or <symbol>TCP_KEEPALIVE</> symbols, and on
|
|
Windows; on other systems, it must be zero. This parameter is ignored
|
|
for connections made via a Unix-domain socket.
|
|
</para>
|
|
<note>
|
|
<para>
|
|
On Windows, a value of 0 will set this parameter to 2 hours,
|
|
since Windows does not provide a way to read the system default value.
|
|
</para>
|
|
</note>
|
|
</listitem>
|
|
</varlistentry>
|
|
|
|
<varlistentry id="guc-tcp-keepalives-interval" xreflabel="tcp_keepalives_interval">
|
|
<term><varname>tcp_keepalives_interval</varname> (<type>integer</type>)</term>
|
|
<indexterm>
|
|
<primary><varname>tcp_keepalives_interval</> configuration parameter</primary>
|
|
</indexterm>
|
|
<listitem>
|
|
<para>
|
|
Specifies the number of seconds between sending keepalives on an
|
|
otherwise idle connection. A value of 0 uses the system default.
|
|
This parameter is supported only on systems that support the
|
|
<symbol>TCP_KEEPINTVL</> symbol, and on Windows; on other systems, it
|
|
must be zero. This parameter is ignored for connections made via a
|
|
Unix-domain socket.
|
|
</para>
|
|
<note>
|
|
<para>
|
|
On Windows, a value of 0 will set this parameter to 1 second,
|
|
since Windows does not provide a way to read the system default value.
|
|
</para>
|
|
</note>
|
|
</listitem>
|
|
</varlistentry>
|
|
|
|
<varlistentry id="guc-tcp-keepalives-count" xreflabel="tcp_keepalives_count">
|
|
<term><varname>tcp_keepalives_count</varname> (<type>integer</type>)</term>
|
|
<indexterm>
|
|
<primary><varname>tcp_keepalives_count</> configuration parameter</primary>
|
|
</indexterm>
|
|
<listitem>
|
|
<para>
|
|
Specifies the number of keepalive packets to send on an otherwise idle
|
|
connection. A value of 0 uses the system default. This parameter is
|
|
supported only on systems that support the <symbol>TCP_KEEPCNT</>
|
|
symbol; on other systems, it must be zero. This parameter is ignored
|
|
for connections made via a Unix-domain socket.
|
|
</para>
|
|
<note>
|
|
<para>
|
|
This parameter is not supported on Windows, and must be zero.
|
|
</para>
|
|
</note>
|
|
</listitem>
|
|
</varlistentry>
|
|
|
|
</variablelist>
|
|
</sect2>
|
|
<sect2 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 closes the connection. This prevents
|
|
hung clients from occupying a connection indefinitely.
|
|
The default is one minute (<literal>1m</>).
|
|
This parameter can only be set in the <filename>postgresql.conf</>
|
|
file or on the server command line.
|
|
</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 <literal>off</>. This parameter can only be set at server
|
|
start. <acronym>SSL</> communication is only possible with
|
|
TCP/IP connections.
|
|
</para>
|
|
</listitem>
|
|
</varlistentry>
|
|
|
|
<varlistentry id="guc-ssl-renegotiation-limit" xreflabel="ssl_renegotiation_limit">
|
|
<term><varname>ssl_renegotiation_limit</varname> (<type>integer</type>)</term>
|
|
<indexterm>
|
|
<primary><varname>ssl_renegotiation_limit</> configuration parameter</primary>
|
|
</indexterm>
|
|
<listitem>
|
|
<para>
|
|
Specifies how much data can flow over an <acronym>SSL</>-encrypted
|
|
connection before renegotiation of the session keys will take
|
|
place. Renegotiation decreases an attacker's chances of doing
|
|
cryptanalysis when large amounts of traffic can be examined, but it
|
|
also carries a large performance penalty. The sum of sent and received
|
|
traffic is used to check the limit. If this parameter is set to 0,
|
|
renegotiation is disabled. The default is <literal>512MB</>.
|
|
</para>
|
|
<note>
|
|
<para>
|
|
SSL libraries from before November 2009 are insecure when using SSL
|
|
renegotiation, due to a vulnerability in the SSL protocol. As a
|
|
stop-gap fix for this vulnerability, some vendors shipped SSL
|
|
libraries incapable of doing renegotiation. If any such libraries
|
|
are in use on the client or server, SSL renegotiation should be
|
|
disabled.
|
|
</para>
|
|
</note>
|
|
</listitem>
|
|
</varlistentry>
|
|
|
|
<varlistentry id="guc-ssl-ciphers" xreflabel="ssl_ciphers">
|
|
<term><varname>ssl_ciphers</varname> (<type>string</type>)</term>
|
|
<indexterm>
|
|
<primary><varname>ssl_ciphers</> configuration parameter</primary>
|
|
</indexterm>
|
|
<listitem>
|
|
<para>
|
|
Specifies a list of <acronym>SSL</> ciphers that are allowed to be
|
|
used on secure connections. See the <application>openssl</>
|
|
manual page for a list of supported ciphers.
|
|
</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"> or
|
|
<xref linkend="sql-alterrole">
|
|
without writing either <literal>ENCRYPTED</> or
|
|
<literal>UNENCRYPTED</>, this parameter determines whether the
|
|
password is to be encrypted. The default is <literal>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"> or <xref linkend="gssapi-auth">
|
|
for details. This parameter can only be set in the
|
|
<filename>postgresql.conf</> file or on the server command line.
|
|
</para>
|
|
</listitem>
|
|
</varlistentry>
|
|
|
|
<varlistentry id="guc-krb-srvname" xreflabel="krb_srvname">
|
|
<term><varname>krb_srvname</varname> (<type>string</type>)</term>
|
|
<indexterm>
|
|
<primary><varname>krb_srvname</> configuration parameter</primary>
|
|
</indexterm>
|
|
<listitem>
|
|
<para>
|
|
Sets the Kerberos service name. See <xref linkend="kerberos-auth">
|
|
for details. This parameter can only be set in the
|
|
<filename>postgresql.conf</> file or on the server command line.
|
|
</para>
|
|
</listitem>
|
|
</varlistentry>
|
|
|
|
<varlistentry id="guc-krb-caseins-users" xreflabel="krb_caseins_users">
|
|
<term><varname>krb_caseins_users</varname> (<type>boolean</type>)</term>
|
|
<indexterm>
|
|
<primary><varname>krb_caseins_users</varname> configuration parameter</primary>
|
|
</indexterm>
|
|
<listitem>
|
|
<para>
|
|
Sets whether Kerberos and GSSAPI user names should be treated
|
|
case-insensitively.
|
|
The default is <literal>off</> (case sensitive). This parameter can only be
|
|
set in the <filename>postgresql.conf</> file or on the server command line.
|
|
</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 parameter enables per-database user names. It is off by default.
|
|
This parameter can only be set in the <filename>postgresql.conf</>
|
|
file or on the server command line.
|
|
</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 are 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 parameter enabled, you can still create ordinary global
|
|
users. Simply append <literal>@</> when specifying the user
|
|
name in the client, e.g. <literal>joe@</>. The <literal>@</>
|
|
will be stripped off before the user name is looked up by the
|
|
server.
|
|
</para>
|
|
|
|
<para>
|
|
<varname>db_user_namespace</> causes the client's and
|
|
server's user name representation to differ.
|
|
Authentication checks are always done with the server's user name
|
|
so authentication methods must be configured for the
|
|
server's user name, not the client's. Because
|
|
<literal>md5</> uses the user name as salt on both the
|
|
client and server, <literal>md5</> cannot be used with
|
|
<varname>db_user_namespace</>.
|
|
</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>
|
|
</sect2>
|
|
</sect1>
|
|
|
|
<sect1 id="runtime-config-resource">
|
|
<title>Resource Consumption</title>
|
|
|
|
<sect2 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 amount of memory the database server uses for shared
|
|
memory buffers. The default is typically 32 megabytes
|
|
(<literal>32MB</>), but might be less if your kernel settings will
|
|
not support it (as determined during <application>initdb</>).
|
|
This setting must be at least 128 kilobytes. (Non-default
|
|
values of <symbol>BLCKSZ</symbol> change the minimum.) However,
|
|
settings significantly higher than the minimum are usually needed
|
|
for good performance. This parameter can only be set at server start.
|
|
</para>
|
|
|
|
<para>
|
|
If you have a dedicated database server with 1GB or more of RAM, a
|
|
reasonable starting value for <varname>shared_buffers</varname> is 25%
|
|
of the memory in your system. There are some workloads where even
|
|
large settings for <varname>shared_buffers</varname> are effective, but
|
|
because <productname>PostgreSQL</productname> also relies on the
|
|
operating system cache, it is unlikely that an allocation of more than
|
|
40% of RAM to <varname>shared_buffers</varname> will work better than a
|
|
smaller amount. Larger settings for <varname>shared_buffers</varname>
|
|
usually require a corresponding increase in
|
|
<varname>checkpoint_segments</varname>, in order to spread out the
|
|
process of writing large quantities of new or changed data over a
|
|
longer period of time.
|
|
</para>
|
|
|
|
<para>
|
|
On systems with less than 1GB of RAM, a smaller percentage of RAM is
|
|
appropriate, so as to leave adequate space for the operating system.
|
|
Also, on Windows, large values for <varname>shared_buffers</varname>
|
|
aren't as effective. You may find better results keeping the setting
|
|
relatively low and using the operating system cache more instead. The
|
|
useful range for <varname>shared_buffers</varname> on Windows systems
|
|
is generally from 64MB to 512MB.
|
|
</para>
|
|
|
|
<para>
|
|
Increasing this parameter might 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-temp-buffers" xreflabel="temp_buffers">
|
|
<term><varname>temp_buffers</varname> (<type>integer</type>)</term>
|
|
<indexterm>
|
|
<primary><varname>temp_buffers</> configuration parameter</primary>
|
|
</indexterm>
|
|
<listitem>
|
|
<para>
|
|
Sets the maximum number of temporary buffers used by each database
|
|
session. These are session-local buffers used only for access to
|
|
temporary tables. The default is eight megabytes
|
|
(<literal>8MB</>). The setting can be changed within individual
|
|
sessions, but only before the first use of temporary tables
|
|
within the session; subsequent attempts to change the value will
|
|
have no effect on that session.
|
|
</para>
|
|
|
|
<para>
|
|
A session will allocate temporary buffers as needed up to the limit
|
|
given by <varname>temp_buffers</>. The cost of setting a large
|
|
value in sessions that do not actually need many temporary
|
|
buffers is only a buffer descriptor, or about 64 bytes, per
|
|
increment in <varname>temp_buffers</>. However if a buffer is
|
|
actually used an additional 8192 bytes will be consumed for it
|
|
(or in general, <symbol>BLCKSZ</symbol> bytes).
|
|
</para>
|
|
</listitem>
|
|
</varlistentry>
|
|
|
|
<varlistentry id="guc-max-prepared-transactions" xreflabel="max_prepared_transactions">
|
|
<term><varname>max_prepared_transactions</varname> (<type>integer</type>)</term>
|
|
<indexterm>
|
|
<primary><varname>max_prepared_transactions</> configuration parameter</primary>
|
|
</indexterm>
|
|
<listitem>
|
|
<para>
|
|
Sets the maximum number of transactions that can be in the
|
|
<quote>prepared</> state simultaneously (see <xref
|
|
linkend="sql-prepare-transaction">).
|
|
Setting this parameter to zero (which is the default)
|
|
disables the prepared-transaction feature.
|
|
This parameter can only be set at server start.
|
|
</para>
|
|
|
|
<para>
|
|
If you are not planning to use prepared transactions, this parameter
|
|
should be set to zero to prevent accidental creation of prepared
|
|
transactions. If you are using prepared transactions, you will
|
|
probably want <varname>max_prepared_transactions</varname> to be at
|
|
least as large as <xref linkend="guc-max-connections">, so that every
|
|
session can have a prepared transaction pending.
|
|
</para>
|
|
|
|
<para>
|
|
Increasing this parameter might 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>
|
|
|
|
<para>
|
|
When running a standby server, you must set this parameter to the
|
|
same or higher value than on the master server. Otherwise, queries
|
|
will not be allowed in the standby server.
|
|
</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 writing to temporary disk files. The value
|
|
defaults to one megabyte (<literal>1MB</>).
|
|
Note that for a complex query, several sort or hash operations might be
|
|
running in parallel; each operation will be allowed to use as much memory
|
|
as this value specifies before it starts to write data into temporary
|
|
files. Also, several running sessions could be doing such operations
|
|
concurrently. Therefore, 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 by maintenance
|
|
operations, such as <command>VACUUM</command>, <command>CREATE
|
|
INDEX</>, and <command>ALTER TABLE ADD FOREIGN KEY</>. It defaults
|
|
to 16 megabytes (<literal>16MB</>). Since only one of these
|
|
operations can be executed at a time by a database session, and
|
|
an installation normally doesn't have many of them running
|
|
concurrently, it's safe to set this value significantly larger
|
|
than <varname>work_mem</varname>. Larger settings might improve
|
|
performance for vacuuming and for restoring database dumps.
|
|
</para>
|
|
<para>
|
|
Note that when autovacuum runs, up to
|
|
<xref linkend="guc-autovacuum-max-workers"> times this memory may be
|
|
allocated, so be careful not to set the default value too high.
|
|
</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. The default setting is two
|
|
megabytes (<literal>2MB</>), which is conservatively small and
|
|
unlikely to risk crashes. However, it might be too small to allow
|
|
execution of complex functions. Only superusers can change this
|
|
setting.
|
|
</para>
|
|
|
|
<para>
|
|
Setting <varname>max_stack_depth</> higher than
|
|
the actual kernel limit will mean that a runaway recursive function
|
|
can crash an individual backend process. On platforms where
|
|
<productname>PostgreSQL</productname> can determine the kernel limit,
|
|
the server will not allow this variable to be set to an unsafe
|
|
value. However, not all platforms provide the information,
|
|
so caution is recommended in selecting a value.
|
|
</para>
|
|
</listitem>
|
|
</varlistentry>
|
|
|
|
</variablelist>
|
|
</sect2>
|
|
|
|
<sect2 id="runtime-config-resource-disk">
|
|
<title>Disk</title>
|
|
|
|
<variablelist>
|
|
<varlistentry id="guc-temp-file-limit" xreflabel="temp_file_limit">
|
|
<term><varname>temp_file_limit</varname> (<type>integer</type>)</term>
|
|
<indexterm>
|
|
<primary><varname>temp_file_limit</> configuration parameter</primary>
|
|
</indexterm>
|
|
<listitem>
|
|
<para>
|
|
Specifies the maximum amount of disk space that a session can use
|
|
for temporary files, such as sort and hash temporary files, or the
|
|
storage file for a held cursor.
|
|
The value is specified in kilobytes, and <literal>-1</> (the
|
|
default) means no limit.
|
|
Only superusers can change this setting.
|
|
</para>
|
|
<para>
|
|
This setting constrains the total space used at any instant by all
|
|
temporary files used by a given <productname>PostgreSQL</> session.
|
|
It should be noted that disk space used for explicit temporary
|
|
tables, as opposed to temporary files used behind-the-scenes in query
|
|
execution, does <emphasis>not</emphasis> count against this limit.
|
|
</para>
|
|
</listitem>
|
|
</varlistentry>
|
|
|
|
</variablelist>
|
|
</sect2>
|
|
|
|
<sect2 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 one thousand files. 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 actually support if many processes all try to open
|
|
that many files. If you find yourself seeing <quote>Too many open
|
|
files</> failures, try reducing this setting.
|
|
This parameter can only be set at server start.
|
|
</para>
|
|
</listitem>
|
|
</varlistentry>
|
|
|
|
<varlistentry id="guc-shared-preload-libraries" xreflabel="shared_preload_libraries">
|
|
<term><varname>shared_preload_libraries</varname> (<type>string</type>)</term>
|
|
<indexterm>
|
|
<primary><varname>shared_preload_libraries</> configuration parameter</primary>
|
|
</indexterm>
|
|
<listitem>
|
|
<para>
|
|
This variable specifies one or more shared libraries
|
|
to be preloaded at server start. For example,
|
|
<literal>'$libdir/mylib'</literal> would cause
|
|
<literal>mylib.so</> (or on some platforms,
|
|
<literal>mylib.sl</>) to be preloaded from the installation's
|
|
standard library directory.
|
|
All library names are converted to lower case unless double-quoted.
|
|
If more than one library is to be loaded, separate their names
|
|
with commas. This parameter can only be set at server start.
|
|
</para>
|
|
|
|
<para>
|
|
<productname>PostgreSQL</productname> procedural language
|
|
libraries can be preloaded in this way, typically by using the
|
|
syntax <literal>'$libdir/plXXX'</literal> where
|
|
<literal>XXX</literal> is <literal>pgsql</>, <literal>perl</>,
|
|
<literal>tcl</>, or <literal>python</>.
|
|
</para>
|
|
|
|
<para>
|
|
By preloading a shared library, the library startup time is avoided
|
|
when the library is first used. However, the time to start each new
|
|
server process might increase slightly, even if that process never
|
|
uses the library. So this parameter is recommended only for
|
|
libraries that will be used in most sessions.
|
|
</para>
|
|
|
|
<note>
|
|
<para>
|
|
On Windows hosts, preloading a library at server start will not reduce
|
|
the time required to start each new server process; each server process
|
|
will re-load all preload libraries. However, <varname>shared_preload_libraries
|
|
</varname> is still useful on Windows hosts because some shared libraries may
|
|
need to perform certain operations that only take place at postmaster start
|
|
(for example, a shared library may need to reserve lightweight locks
|
|
or shared memory and you can't do that after the postmaster has started).
|
|
</para>
|
|
</note>
|
|
<para>
|
|
If a specified library is not found,
|
|
the server will fail to start.
|
|
</para>
|
|
|
|
<para>
|
|
Every PostgreSQL-supported library has a <quote>magic
|
|
block</> that is checked to guarantee compatibility.
|
|
For this reason, non-PostgreSQL libraries cannot be
|
|
loaded in this way.
|
|
</para>
|
|
</listitem>
|
|
</varlistentry>
|
|
|
|
</variablelist>
|
|
</sect2>
|
|
|
|
<sect2 id="runtime-config-resource-vacuum-cost">
|
|
<title>Cost-based Vacuum Delay</title>
|
|
|
|
<para>
|
|
During the execution of <xref linkend="sql-vacuum">
|
|
and <xref linkend="sql-analyze">
|
|
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 short period of time, as 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 where it is not
|
|
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 for manually issued
|
|
<command>VACUUM</command> commands. 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 zero, 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 might have the same results as setting it
|
|
to the next higher multiple of 10.
|
|
</para>
|
|
|
|
<para>
|
|
When using cost-based vacuuming, appropriate values for
|
|
<varname>vacuum_cost_delay</> are usually quite small, perhaps
|
|
10 or 20 milliseconds. Adjusting vacuum's resource consumption
|
|
is best done by changing the other vacuum cost parameters.
|
|
</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 one.
|
|
</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>
|
|
</sect2>
|
|
|
|
<sect2 id="runtime-config-resource-background-writer">
|
|
<title>Background Writer</title>
|
|
|
|
<para>
|
|
There is a separate server
|
|
process called the <firstterm>background writer</>, whose function
|
|
is to issue writes of <quote>dirty</> (new or modified) shared
|
|
buffers. It writes shared buffers so server processes handling
|
|
user queries seldom or never need to wait for a write to occur.
|
|
However, the background writer does cause a net overall
|
|
increase in I/O load, because while a repeatedly-dirtied page might
|
|
otherwise be written only once per checkpoint interval, the
|
|
background writer might write it several times as it is dirtied
|
|
in the same interval. The parameters discussed in this subsection
|
|
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 milliseconds
|
|
(<literal>200ms</>). 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 might have the same results as setting it to the next higher
|
|
multiple of 10. This parameter can only be set in the
|
|
<filename>postgresql.conf</> file or on the server command line.
|
|
</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
|
|
by the background writer. Setting this to zero disables
|
|
background writing (except for checkpoint activity).
|
|
The default value is 100 buffers.
|
|
This parameter can only be set in the <filename>postgresql.conf</>
|
|
file or on the server command line.
|
|
</para>
|
|
</listitem>
|
|
</varlistentry>
|
|
|
|
<varlistentry id="guc-bgwriter-lru-multiplier" xreflabel="bgwriter_lru_multiplier">
|
|
<term><varname>bgwriter_lru_multiplier</varname> (<type>floating point</type>)</term>
|
|
<indexterm>
|
|
<primary><varname>bgwriter_lru_multiplier</> configuration parameter</primary>
|
|
</indexterm>
|
|
<listitem>
|
|
<para>
|
|
The number of dirty buffers written in each round is based on the
|
|
number of new buffers that have been needed by server processes
|
|
during recent rounds. The average recent need is multiplied by
|
|
<varname>bgwriter_lru_multiplier</> to arrive at an estimate of the
|
|
number of buffers that will be needed during the next round. Dirty
|
|
buffers are written until there are that many clean, reusable buffers
|
|
available. (However, no more than <varname>bgwriter_lru_maxpages</>
|
|
buffers will be written per round.)
|
|
Thus, a setting of 1.0 represents a <quote>just in time</> policy
|
|
of writing exactly the number of buffers predicted to be needed.
|
|
Larger values provide some cushion against spikes in demand,
|
|
while smaller values intentionally leave writes to be done by
|
|
server processes.
|
|
The default is 2.0.
|
|
This parameter can only be set in the <filename>postgresql.conf</>
|
|
file or on the server command line.
|
|
</para>
|
|
</listitem>
|
|
</varlistentry>
|
|
</variablelist>
|
|
|
|
<para>
|
|
Smaller values of <varname>bgwriter_lru_maxpages</varname> and
|
|
<varname>bgwriter_lru_multiplier</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.
|
|
</para>
|
|
</sect2>
|
|
|
|
<sect2 id="runtime-config-resource-async-behavior">
|
|
<title>Asynchronous Behavior</title>
|
|
|
|
<variablelist>
|
|
<varlistentry id="guc-effective-io-concurrency" xreflabel="effective_io_concurrency">
|
|
<term><varname>effective_io_concurrency</varname> (<type>integer</type>)</term>
|
|
<indexterm>
|
|
<primary><varname>effective_io_concurrency</> configuration parameter</primary>
|
|
</indexterm>
|
|
<listitem>
|
|
<para>
|
|
Sets the number of concurrent disk I/O operations that
|
|
<productname>PostgreSQL</> expects can be executed
|
|
simultaneously. Raising this value will increase the number of I/O
|
|
operations that any individual <productname>PostgreSQL</> session
|
|
attempts to initiate in parallel. The allowed range is 1 to 1000,
|
|
or zero to disable issuance of asynchronous I/O requests. Currently,
|
|
this setting only affects bitmap heap scans.
|
|
</para>
|
|
|
|
<para>
|
|
A good starting point for this setting is the number of separate
|
|
drives comprising a RAID 0 stripe or RAID 1 mirror being used for the
|
|
database. (For RAID 5 the parity drive should not be counted.)
|
|
However, if the database is often busy with multiple queries issued in
|
|
concurrent sessions, lower values may be sufficient to keep the disk
|
|
array busy. A value higher than needed to keep the disks busy will
|
|
only result in extra CPU overhead.
|
|
</para>
|
|
|
|
<para>
|
|
For more exotic systems, such as memory-based storage or a RAID array
|
|
that is limited by bus bandwidth, the correct value might be the
|
|
number of I/O paths available. Some experimentation may be needed
|
|
to find the best value.
|
|
</para>
|
|
|
|
<para>
|
|
Asynchronous I/O depends on an effective <function>posix_fadvise</>
|
|
function, which some operating systems lack. If the function is not
|
|
present then setting this parameter to anything but zero will result
|
|
in an error. On some operating systems (e.g., Solaris), the function
|
|
is present but does not actually do anything.
|
|
</para>
|
|
</listitem>
|
|
</varlistentry>
|
|
</variablelist>
|
|
</sect2>
|
|
</sect1>
|
|
|
|
<sect1 id="runtime-config-wal">
|
|
<title>Write Ahead Log</title>
|
|
|
|
<para>
|
|
See also <xref linkend="wal-configuration"> for details on WAL
|
|
and checkpoint tuning.
|
|
</para>
|
|
|
|
<sect2 id="runtime-config-wal-settings">
|
|
<title>Settings</title>
|
|
<variablelist>
|
|
|
|
<varlistentry id="guc-wal-level" xreflabel="wal_level">
|
|
<term><varname>wal_level</varname> (<type>enum</type>)</term>
|
|
<indexterm>
|
|
<primary><varname>wal_level</> configuration parameter</primary>
|
|
</indexterm>
|
|
<listitem>
|
|
<para>
|
|
<varname>wal_level</> determines how much information is written
|
|
to the WAL. The default value is <literal>minimal</>, which writes
|
|
only the information needed to recover from a crash or immediate
|
|
shutdown. <literal>archive</> adds logging required for WAL archiving,
|
|
and <literal>hot_standby</> further adds information required to run
|
|
read-only queries on a standby server.
|
|
This parameter can only be set at server start.
|
|
</para>
|
|
<para>
|
|
In <literal>minimal</> level, WAL-logging of some bulk
|
|
operations can be safely skipped, which can make those
|
|
operations much faster (see <xref linkend="populate-pitr">).
|
|
Operations in which this optimization can be applied include:
|
|
<simplelist>
|
|
<member><command>CREATE TABLE AS</></member>
|
|
<member><command>CREATE INDEX</></member>
|
|
<member><command>CLUSTER</></member>
|
|
<member><command>COPY</> into tables that were created or truncated in the same
|
|
transaction</member>
|
|
</simplelist>
|
|
But minimal WAL does not contain
|
|
enough information to reconstruct the data from a base backup and the
|
|
WAL logs, so either <literal>archive</> or <literal>hot_standby</>
|
|
level must be used to enable
|
|
WAL archiving (<xref linkend="guc-archive-mode">) and streaming
|
|
replication.
|
|
</para>
|
|
<para>
|
|
In <literal>hot_standby</> level, the same information is logged as
|
|
with <literal>archive</>, plus information needed to reconstruct
|
|
the status of running transactions from the WAL. To enable read-only
|
|
queries on a standby server, <varname>wal_level</> must be set to
|
|
<literal>hot_standby</> on the primary, and
|
|
<xref linkend="guc-hot-standby"> must be enabled in the standby. It is
|
|
thought that there is
|
|
little measurable difference in performance between using
|
|
<literal>hot_standby</> and <literal>archive</> levels, so feedback
|
|
is welcome if any production impacts are noticeable.
|
|
</para>
|
|
</listitem>
|
|
</varlistentry>
|
|
|
|
<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 parameter is on, the <productname>PostgreSQL</> server
|
|
will try to make sure that updates are physically written to
|
|
disk, by issuing <function>fsync()</> system calls or various
|
|
equivalent methods (see <xref linkend="guc-wal-sync-method">).
|
|
This ensures that the database cluster can recover to a
|
|
consistent state after an operating system or hardware crash.
|
|
</para>
|
|
|
|
<para>
|
|
While turning off <varname>fsync</varname> is often a performance
|
|
benefit, this can result in unrecoverable data corruption in
|
|
the event of a power failure or system crash. Thus it
|
|
is only advisable to turn off <varname>fsync</varname> if
|
|
you can easily recreate your entire database from external
|
|
data.
|
|
</para>
|
|
|
|
<para>
|
|
Examples of safe circumstances for turning off
|
|
<varname>fsync</varname> include the initial loading of a new
|
|
database cluster from a backup file, using a database cluster
|
|
for processing a batch of data after which the database
|
|
will be thrown away and recreated,
|
|
or for a read-only database clone which
|
|
gets recreated frequently and is not used for failover. High
|
|
quality hardware alone is not a sufficient justification for
|
|
turning off <varname>fsync</varname>.
|
|
</para>
|
|
|
|
<para>
|
|
In many situations, turning off <xref linkend="guc-synchronous-commit">
|
|
for noncritical transactions can provide much of the potential
|
|
performance benefit of turning off <varname>fsync</varname>, without
|
|
the attendant risks of data corruption.
|
|
</para>
|
|
|
|
<para>
|
|
<varname>fsync</varname> can only be set in the <filename>postgresql.conf</>
|
|
file or on the server command line.
|
|
If you turn this parameter off, also consider turning off
|
|
<xref linkend="guc-full-page-writes">.
|
|
</para>
|
|
</listitem>
|
|
</varlistentry>
|
|
|
|
<varlistentry id="guc-synchronous-commit" xreflabel="synchronous_commit">
|
|
<term><varname>synchronous_commit</varname> (<type>enum</type>)</term>
|
|
<indexterm>
|
|
<primary><varname>synchronous_commit</> configuration parameter</primary>
|
|
</indexterm>
|
|
<listitem>
|
|
<para>
|
|
Specifies whether transaction commit will wait for WAL records
|
|
to be written to disk before the command returns a <quote>success</>
|
|
indication to the client. Valid values are <literal>on</>,
|
|
<literal>local</>, and <literal>off</>. The default, and safe, value
|
|
is <literal>on</>. When <literal>off</>, there can be a delay between
|
|
when success is reported to the client and when the transaction is
|
|
really guaranteed to be safe against a server crash. (The maximum
|
|
delay is three times <xref linkend="guc-wal-writer-delay">.) Unlike
|
|
<xref linkend="guc-fsync">, setting this parameter to <literal>off</>
|
|
does not create any risk of database inconsistency: an operating
|
|
system or database crash might
|
|
result in some recent allegedly-committed transactions being lost, but
|
|
the database state will be just the same as if those transactions had
|
|
been aborted cleanly. So, turning <varname>synchronous_commit</> off
|
|
can be a useful alternative when performance is more important than
|
|
exact certainty about the durability of a transaction. For more
|
|
discussion see <xref linkend="wal-async-commit">.
|
|
</para>
|
|
<para>
|
|
If <xref linkend="guc-synchronous-standby-names"> is set, this
|
|
parameter also controls whether or not transaction commit will wait
|
|
for the transaction's WAL records to be flushed to disk and replicated
|
|
to the standby server. The commit wait will last until a reply from
|
|
the current synchronous standby indicates it has written the commit
|
|
record of the transaction to durable storage. If synchronous
|
|
replication is in use, it will normally be sensible either to wait
|
|
both for WAL records to reach both the local and remote disks, or
|
|
to allow the transaction to commit asynchronously. However, the
|
|
special value <literal>local</> is available for transactions that
|
|
wish to wait for local flush to disk, but not synchronous replication.
|
|
</para>
|
|
<para>
|
|
This parameter can be changed at any time; the behavior for any
|
|
one transaction is determined by the setting in effect when it
|
|
commits. It is therefore possible, and useful, to have some
|
|
transactions commit synchronously and others asynchronously.
|
|
For example, to make a single multistatement transaction commit
|
|
asynchronously when the default is the opposite, issue <command>SET
|
|
LOCAL synchronous_commit TO OFF</> within the transaction.
|
|
</para>
|
|
</listitem>
|
|
</varlistentry>
|
|
|
|
<varlistentry id="guc-wal-sync-method" xreflabel="wal_sync_method">
|
|
<term><varname>wal_sync_method</varname> (<type>enum</type>)</term>
|
|
<indexterm>
|
|
<primary><varname>wal_sync_method</> configuration parameter</primary>
|
|
</indexterm>
|
|
<listitem>
|
|
<para>
|
|
Method used for forcing WAL updates out to disk.
|
|
If <varname>fsync</varname> is off then this setting is irrelevant,
|
|
since WAL file updates will not be forced out at all.
|
|
Possible values are:
|
|
</para>
|
|
<itemizedlist>
|
|
<listitem>
|
|
<para>
|
|
<literal>open_datasync</> (write WAL files with <function>open()</> option <symbol>O_DSYNC</>)
|
|
</para>
|
|
</listitem>
|
|
<listitem>
|
|
<para>
|
|
<literal>fdatasync</> (call <function>fdatasync()</> at each commit)
|
|
</para>
|
|
</listitem>
|
|
<listitem>
|
|
<para>
|
|
<literal>fsync</> (call <function>fsync()</> at each commit)
|
|
</para>
|
|
</listitem>
|
|
<listitem>
|
|
<para>
|
|
<literal>fsync_writethrough</> (call <function>fsync()</> at each commit, forcing write-through of any disk write cache)
|
|
</para>
|
|
</listitem>
|
|
<listitem>
|
|
<para>
|
|
<literal>open_sync</> (write WAL files with <function>open()</> option <symbol>O_SYNC</>)
|
|
</para>
|
|
</listitem>
|
|
</itemizedlist>
|
|
<para>
|
|
The <literal>open_</>* options also use <literal>O_DIRECT</> if available.
|
|
Not all of these choices are available on all platforms.
|
|
The default is the first method in the above list that is supported
|
|
by the platform, except that <literal>fdatasync</> is the default on
|
|
Linux. The default is not necessarily ideal; it might be
|
|
necessary to change this setting or other aspects of your system
|
|
configuration in order to create a crash-safe configuration or
|
|
achieve optimal performance.
|
|
These aspects are discussed in <xref linkend="wal-reliability">.
|
|
This parameter can only be set in the <filename>postgresql.conf</>
|
|
file or on the server command line.
|
|
</para>
|
|
</listitem>
|
|
</varlistentry>
|
|
|
|
<varlistentry id="guc-full-page-writes" xreflabel="full_page_writes">
|
|
<indexterm>
|
|
<primary><varname>full_page_writes</> configuration parameter</primary>
|
|
</indexterm>
|
|
<term><varname>full_page_writes</varname> (<type>boolean</type>)</term>
|
|
<listitem>
|
|
<para>
|
|
When this parameter is on, the <productname>PostgreSQL</> server
|
|
writes the entire content of each disk page to WAL during the
|
|
first modification of that page after a checkpoint.
|
|
This is needed because
|
|
a page write that is in process during an operating system crash might
|
|
be only partially completed, leading to an on-disk page
|
|
that contains a mix of old and new data. The row-level change data
|
|
normally stored in WAL will not be enough to completely restore
|
|
such a page during post-crash recovery. Storing the full page image
|
|
guarantees that the page can be correctly restored, but at the price
|
|
of increasing the amount of data that must be written to WAL.
|
|
(Because WAL replay always starts from a checkpoint, it is sufficient
|
|
to do this during the first change of each page after a checkpoint.
|
|
Therefore, one way to reduce the cost of full-page writes is to
|
|
increase the checkpoint interval parameters.)
|
|
</para>
|
|
|
|
<para>
|
|
Turning this parameter off speeds normal operation, but
|
|
might lead to either unrecoverable data corruption, or silent
|
|
data corruption, after a system failure. The risks are similar to turning off
|
|
<varname>fsync</varname>, though smaller, and it should be turned off
|
|
only based on the same circumstances recommended for that parameter.
|
|
</para>
|
|
|
|
<para>
|
|
Turning off this parameter does not affect use of
|
|
WAL archiving for point-in-time recovery (PITR)
|
|
(see <xref linkend="continuous-archiving">).
|
|
</para>
|
|
|
|
<para>
|
|
This parameter can only be set in the <filename>postgresql.conf</>
|
|
file or on the server command line.
|
|
The default is <literal>on</>.
|
|
</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>
|
|
The amount of shared memory used for WAL data that has not yet been
|
|
written to disk. The default setting of -1 selects a size equal to
|
|
1/32nd (about 3%) of <xref linkend="guc-shared-buffers">, but not less
|
|
than <literal>64kB</literal> nor more than the size of one WAL
|
|
segment, typically <literal>16MB</literal>. This value can be set
|
|
manually if the automatic choice is too large or too small,
|
|
but any positive value less than <literal>32kB</literal> will be
|
|
treated as <literal>32kB</literal>.
|
|
This parameter can only be set at server start.
|
|
</para>
|
|
|
|
<para>
|
|
The contents of the WAL buffers are written out to disk at every
|
|
transaction commit, so extremely large values are unlikely to
|
|
provide a significant benefit. However, setting this value to at
|
|
least a few megabytes can improve write performance on a busy
|
|
server where many clients are committing at once. The auto-tuning
|
|
selected by the default setting of -1 should give reasonable
|
|
results in most cases.
|
|
</para>
|
|
|
|
<para>
|
|
Increasing this parameter might 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-wal-writer-delay" xreflabel="wal_writer_delay">
|
|
<term><varname>wal_writer_delay</varname> (<type>integer</type>)</term>
|
|
<indexterm>
|
|
<primary><varname>wal_writer_delay</> configuration parameter</primary>
|
|
</indexterm>
|
|
<listitem>
|
|
<para>
|
|
Specifies the delay between activity rounds for the WAL writer.
|
|
In each round the writer will flush WAL to disk. It then sleeps for
|
|
<varname>wal_writer_delay</> milliseconds, and repeats. The default
|
|
value is 200 milliseconds (<literal>200ms</>). Note that on many
|
|
systems, the effective resolution of sleep delays is 10 milliseconds;
|
|
setting <varname>wal_writer_delay</> to a value that is not a multiple
|
|
of 10 might have the same results as setting it to the next higher
|
|
multiple of 10. This parameter can only be set in the
|
|
<filename>postgresql.conf</> file or on the server command line.
|
|
</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>
|
|
When the commit data for a transaction is flushed to disk, any
|
|
additional commits ready at that time are also flushed out.
|
|
<varname>commit_delay</varname> adds a time delay, set in
|
|
microseconds, before a transaction attempts to
|
|
flush the WAL buffer out to disk. A nonzero delay can allow more
|
|
transactions to be committed with only one flush operation, 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 <varname>commit_delay</> is zero (no delay).
|
|
Since all pending commit data will be written at every flush
|
|
regardless of this setting, it is rare that adding delay
|
|
by increasing this parameter will actually improve performance.
|
|
</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 transactions.
|
|
</para>
|
|
</listitem>
|
|
</varlistentry>
|
|
|
|
</variablelist>
|
|
</sect2>
|
|
<sect2 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 number of log file segments between automatic WAL
|
|
checkpoints (each segment is normally 16 megabytes). The default
|
|
is three segments. Increasing this parameter can increase the
|
|
amount of time needed for crash recovery.
|
|
This parameter can only be set in the <filename>postgresql.conf</>
|
|
file or on the server command line.
|
|
</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 five minutes (<literal>5min</>).
|
|
Increasing this parameter can increase the amount of time needed
|
|
for crash recovery.
|
|
This parameter can only be set in the <filename>postgresql.conf</>
|
|
file or on the server command line.
|
|
</para>
|
|
</listitem>
|
|
</varlistentry>
|
|
|
|
<varlistentry id="guc-checkpoint-completion-target" xreflabel="checkpoint_completion_target">
|
|
<term><varname>checkpoint_completion_target</varname> (<type>floating point</type>)</term>
|
|
<indexterm>
|
|
<primary><varname>checkpoint_completion_target</> configuration parameter</primary>
|
|
</indexterm>
|
|
<listitem>
|
|
<para>
|
|
Specifies the target of checkpoint completion, as a fraction of
|
|
total time between checkpoints. The default is 0.5.
|
|
|
|
This parameter can only be set in the <filename>postgresql.conf</>
|
|
file or on the server command line.
|
|
</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 (which suggests that
|
|
<varname>checkpoint_segments</> ought to be raised). The default is
|
|
30 seconds (<literal>30s</>). Zero disables the warning.
|
|
This parameter can only be set in the <filename>postgresql.conf</>
|
|
file or on the server command line.
|
|
</para>
|
|
</listitem>
|
|
</varlistentry>
|
|
|
|
</variablelist>
|
|
</sect2>
|
|
<sect2 id="runtime-config-wal-archiving">
|
|
<title>Archiving</title>
|
|
|
|
<variablelist>
|
|
<varlistentry id="guc-archive-mode" xreflabel="archive_mode">
|
|
<term><varname>archive_mode</varname> (<type>boolean</type>)</term>
|
|
<indexterm>
|
|
<primary><varname>archive_mode</> configuration parameter</primary>
|
|
</indexterm>
|
|
<listitem>
|
|
<para>
|
|
When <varname>archive_mode</> is enabled, completed WAL segments
|
|
are sent to archive storage by setting
|
|
<xref linkend="guc-archive-command">.
|
|
<varname>archive_mode</> and <varname>archive_command</> are
|
|
separate variables so that <varname>archive_command</> can be
|
|
changed without leaving archiving mode.
|
|
This parameter can only be set at server start.
|
|
<varname>archive_mode</> cannot be enabled when
|
|
<varname>wal_level</> is set to <literal>minimal</>.
|
|
</para>
|
|
</listitem>
|
|
</varlistentry>
|
|
|
|
<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 WAL file
|
|
segment. Any <literal>%p</> in the string is
|
|
replaced by the path name of the file to archive, and any
|
|
<literal>%f</> is replaced by only the file name.
|
|
(The path name is relative to the working directory of the server,
|
|
i.e., the cluster's data directory.)
|
|
Use <literal>%%</> to embed an actual <literal>%</> character in the
|
|
command. It is important for the command to return a zero
|
|
exit status only if it succeeds. For more information see
|
|
<xref linkend="backup-archiving-wal">.
|
|
</para>
|
|
<para>
|
|
This parameter can only be set in the <filename>postgresql.conf</>
|
|
file or on the server command line. It is ignored unless
|
|
<varname>archive_mode</> was enabled at server start.
|
|
If <varname>archive_command</> is an empty string (the default) while
|
|
<varname>archive_mode</> is enabled, WAL archiving is temporarily
|
|
disabled, but the server continues to accumulate WAL segment files in
|
|
the expectation that a command will soon be provided. Setting
|
|
<varname>archive_command</> to a command that does nothing but
|
|
return true, e.g. <literal>/bin/true</> (<literal>REM</> on
|
|
Windows), effectively disables
|
|
archiving, but also breaks the chain of WAL files needed for
|
|
archive recovery, so it should only be used in unusual circumstances.
|
|
</para>
|
|
</listitem>
|
|
</varlistentry>
|
|
|
|
<varlistentry id="guc-archive-timeout" xreflabel="archive_timeout">
|
|
<term><varname>archive_timeout</varname> (<type>integer</type>)</term>
|
|
<indexterm>
|
|
<primary><varname>archive_timeout</> configuration parameter</primary>
|
|
</indexterm>
|
|
<listitem>
|
|
<para>
|
|
The <xref linkend="guc-archive-command"> is only invoked for
|
|
completed WAL segments. Hence, if your server generates little WAL
|
|
traffic (or has slack periods where it does so), there could be a
|
|
long delay between the completion of a transaction and its safe
|
|
recording in archive storage. To limit how old unarchived
|
|
data can be, you can set <varname>archive_timeout</> to force the
|
|
server to switch to a new WAL segment file periodically. When this
|
|
parameter is greater than zero, the server will switch to a new
|
|
segment file whenever this many seconds have elapsed since the last
|
|
segment file switch, and there has been any database activity,
|
|
including a single checkpoint. (Increasing
|
|
<varname>checkpoint_timeout</> will reduce unnecessary
|
|
checkpoints on an idle system.)
|
|
Note that archived files that are closed early
|
|
due to a forced switch are still the same length as completely full
|
|
files. Therefore, it is unwise to use a very short
|
|
<varname>archive_timeout</> — it will bloat your archive
|
|
storage. <varname>archive_timeout</> settings of a minute or so are
|
|
usually reasonable. You should consider using streaming replication,
|
|
instead of archiving, if you want data to be copied off the master
|
|
server more quickly than that.
|
|
This parameter can only be set in the
|
|
<filename>postgresql.conf</> file or on the server command line.
|
|
</para>
|
|
</listitem>
|
|
</varlistentry>
|
|
|
|
</variablelist>
|
|
</sect2>
|
|
|
|
</sect1>
|
|
|
|
<sect1 id="runtime-config-replication">
|
|
<title>Replication</title>
|
|
|
|
<para>
|
|
These settings control the behavior of the built-in
|
|
<firstterm>streaming replication</> feature (see
|
|
<xref linkend="streaming-replication">). Servers will be either a
|
|
Master or a Standby server. Masters can send data, while Standby(s)
|
|
are always receivers of replicated data. When cascading replication
|
|
(see <xref linkend="cascading-replication">) is used, Standby server(s)
|
|
can also be senders, as well as receivers.
|
|
Parameters are mainly for Sending and Standby servers, though some
|
|
parameters have meaning only on the Master server. Settings may vary
|
|
across the cluster without problems if that is required.
|
|
</para>
|
|
|
|
<sect2 id="runtime-config-replication-sender">
|
|
<title>Sending Server(s)</title>
|
|
|
|
<para>
|
|
These parameters can be set on any server that is
|
|
to send replication data to one or more standby servers.
|
|
The master is always a sending server, so these parameters must
|
|
always be set on the master.
|
|
The role and meaning of these parameters does not change after a
|
|
standby becomes the master.
|
|
</para>
|
|
|
|
<variablelist>
|
|
<varlistentry id="guc-max-wal-senders" xreflabel="max_wal_senders">
|
|
<term><varname>max_wal_senders</varname> (<type>integer</type>)</term>
|
|
<indexterm>
|
|
<primary><varname>max_wal_senders</> configuration parameter</primary>
|
|
</indexterm>
|
|
<listitem>
|
|
<para>
|
|
Specifies the maximum number of concurrent connections from standby
|
|
servers or streaming base backup clients (i.e., the maximum number of
|
|
simultaneously running WAL sender
|
|
processes). The default is zero. This parameter can only be set at
|
|
server start. <varname>wal_level</> must be set to <literal>archive</>
|
|
or <literal>hot_standby</> to allow connections from standby servers.
|
|
</para>
|
|
</listitem>
|
|
</varlistentry>
|
|
|
|
<varlistentry id="guc-wal-keep-segments" xreflabel="wal_keep_segments">
|
|
<term><varname>wal_keep_segments</varname> (<type>integer</type>)</term>
|
|
<indexterm>
|
|
<primary><varname>wal_keep_segments</> configuration parameter</primary>
|
|
</indexterm>
|
|
<listitem>
|
|
<para>
|
|
Specifies the minimum number of past log file segments kept in the
|
|
<filename>pg_xlog</>
|
|
directory, in case a standby server needs to fetch them for streaming
|
|
replication. Each segment is normally 16 megabytes. If a standby
|
|
server connected to the sending server falls behind by more than
|
|
<varname>wal_keep_segments</> segments, the sending server might remove
|
|
a WAL segment still needed by the standby, in which case the
|
|
replication connection will be terminated. Downstream connections
|
|
will also eventually fail as a result. (However, the standby
|
|
server can recover by fetching the segment from archive, if WAL
|
|
archiving is in use.)
|
|
</para>
|
|
|
|
<para>
|
|
This sets only the minimum number of segments retained in
|
|
<filename>pg_xlog</>; the system might need to retain more segments
|
|
for WAL archival or to recover from a checkpoint. If
|
|
<varname>wal_keep_segments</> is zero (the default), the system
|
|
doesn't keep any extra segments for standby purposes, so the number
|
|
of old WAL segments available to standby servers is a function of
|
|
the location of the previous checkpoint and status of WAL
|
|
archiving.
|
|
This parameter can only be set in the
|
|
<filename>postgresql.conf</> file or on the server command line.
|
|
</para>
|
|
</listitem>
|
|
</varlistentry>
|
|
|
|
<varlistentry id="guc-replication-timeout" xreflabel="replication_timeout">
|
|
<term><varname>replication_timeout</varname> (<type>integer</type>)</term>
|
|
<indexterm>
|
|
<primary><varname>replication_timeout</> configuration parameter</primary>
|
|
</indexterm>
|
|
<listitem>
|
|
<para>
|
|
Terminate replication connections that are inactive longer
|
|
than the specified number of milliseconds. This is useful for
|
|
the sending server to detect a standby crash or network outage.
|
|
A value of zero disables the timeout mechanism. This parameter
|
|
can only be set in
|
|
the <filename>postgresql.conf</> file or on the server command line.
|
|
The default value is 60 seconds.
|
|
</para>
|
|
<para>
|
|
To prevent connections from being terminated prematurely,
|
|
<xref linkend="guc-wal-receiver-status-interval">
|
|
must be enabled on the standby, and its value must be less than the
|
|
value of <varname>replication_timeout</>.
|
|
</para>
|
|
</listitem>
|
|
</varlistentry>
|
|
|
|
</variablelist>
|
|
</sect2>
|
|
|
|
<sect2 id="runtime-config-replication-master">
|
|
<title>Master Server</title>
|
|
|
|
<para>
|
|
These parameters can be set on the master/primary server that is
|
|
to send replication data to one or more standby servers.
|
|
Note that in addition to these parameters,
|
|
<xref linkend="guc-wal-level"> must be set appropriately on the master
|
|
server, and optionally WAL archiving can be enabled as
|
|
well (see <xref linkend="runtime-config-wal-archiving">).
|
|
The values of these parameters on standby servers are irrelevant,
|
|
although you may wish to set them there in preparation for the
|
|
possibility of a standby becoming the master.
|
|
</para>
|
|
|
|
<variablelist>
|
|
|
|
<varlistentry id="guc-synchronous-standby-names" xreflabel="synchronous_standby_names">
|
|
<term><varname>synchronous_standby_names</varname> (<type>string</type>)</term>
|
|
<indexterm>
|
|
<primary><varname>synchronous_standby_names</> configuration parameter</primary>
|
|
</indexterm>
|
|
<listitem>
|
|
<para>
|
|
Specifies a comma-separated list of standby names that can support
|
|
<firstterm>synchronous replication</>, as described in
|
|
<xref linkend="synchronous-replication">.
|
|
At any one time there will be at most one active synchronous standby;
|
|
transactions waiting for commit will be allowed to proceed after
|
|
this standby server confirms receipt of their data.
|
|
The synchronous standby will be the first standby named in this list
|
|
that is both currently connected and streaming data in real-time
|
|
(as shown by a state of <literal>streaming</literal> in the
|
|
<link linkend="monitoring-stats-views-table">
|
|
<literal>pg_stat_replication</></link> view).
|
|
Other standby servers appearing later in this list represent potential
|
|
synchronous standbys.
|
|
If the current synchronous standby disconnects for whatever reason,
|
|
it will be replaced immediately with the next-highest-priority standby.
|
|
Specifying more than one standby name can allow very high availability.
|
|
</para>
|
|
<para>
|
|
The name of a standby server for this purpose is the
|
|
<varname>application_name</> setting of the standby, as set in the
|
|
<varname>primary_conninfo</> of the standby's walreceiver. There is
|
|
no mechanism to enforce uniqueness. In case of duplicates one of the
|
|
matching standbys will be chosen to be the synchronous standby, though
|
|
exactly which one is indeterminate.
|
|
The special entry <literal>*</> matches any
|
|
<varname>application_name</>, including the default application name
|
|
of <literal>walreceiver</>.
|
|
</para>
|
|
<para>
|
|
If no synchronous standby names are specified here, then synchronous
|
|
replication is not enabled and transaction commits will not wait for
|
|
replication. This is the default configuration. Even when
|
|
synchronous replication is enabled, individual transactions can be
|
|
configured not to wait for replication by setting the
|
|
<xref linkend="guc-synchronous-commit"> parameter to
|
|
<literal>local</> or <literal>off</>.
|
|
</para>
|
|
<para>
|
|
This parameter can only be set in the <filename>postgresql.conf</>
|
|
file or on the server command line.
|
|
</para>
|
|
</listitem>
|
|
</varlistentry>
|
|
|
|
<varlistentry id="guc-vacuum-defer-cleanup-age" xreflabel="vacuum_defer_cleanup_age">
|
|
<term><varname>vacuum_defer_cleanup_age</varname> (<type>integer</type>)</term>
|
|
<indexterm>
|
|
<primary><varname>vacuum_defer_cleanup_age</> configuration parameter</primary>
|
|
</indexterm>
|
|
<listitem>
|
|
<para>
|
|
Specifies the number of transactions by which <command>VACUUM</> and
|
|
<acronym>HOT</> updates will defer cleanup of dead row versions. The
|
|
default is zero transactions, meaning that dead row versions can be
|
|
removed as soon as possible, that is, as soon as they are no longer
|
|
visible to any open transaction. You may wish to set this to a
|
|
non-zero value on a primary server that is supporting hot standby
|
|
servers, as described in <xref linkend="hot-standby">. This allows
|
|
more time for queries on the standby to complete without incurring
|
|
conflicts due to early cleanup of rows. However, since the value
|
|
is measured in terms of number of write transactions occurring on the
|
|
primary server, it is difficult to predict just how much additional
|
|
grace time will be made available to standby queries.
|
|
This parameter can only be set in the <filename>postgresql.conf</>
|
|
file or on the server command line.
|
|
</para>
|
|
<para>
|
|
You should also consider setting <varname>hot_standby_feedback</>
|
|
on standby server(s) as an alternative to using this parameter.
|
|
</para>
|
|
</listitem>
|
|
</varlistentry>
|
|
|
|
</variablelist>
|
|
</sect2>
|
|
|
|
<sect2 id="runtime-config-replication-standby">
|
|
<title>Standby Servers</title>
|
|
|
|
<para>
|
|
These settings control the behavior of a standby server that is
|
|
to receive replication data. Their values on the master server
|
|
are irrelevant.
|
|
</para>
|
|
|
|
<variablelist>
|
|
|
|
<varlistentry id="guc-hot-standby" xreflabel="hot_standby">
|
|
<term><varname>hot_standby</varname> (<type>boolean</type>)</term>
|
|
<indexterm>
|
|
<primary><varname>hot_standby</> configuration parameter</primary>
|
|
</indexterm>
|
|
<listitem>
|
|
<para>
|
|
Specifies whether or not you can connect and run queries during
|
|
recovery, as described in <xref linkend="hot-standby">.
|
|
The default value is <literal>off</literal>.
|
|
This parameter can only be set at server start. It only has effect
|
|
during archive recovery or in standby mode.
|
|
</para>
|
|
</listitem>
|
|
</varlistentry>
|
|
|
|
<varlistentry id="guc-max-standby-archive-delay" xreflabel="max_standby_archive_delay">
|
|
<term><varname>max_standby_archive_delay</varname> (<type>integer</type>)</term>
|
|
<indexterm>
|
|
<primary><varname>max_standby_archive_delay</> configuration parameter</primary>
|
|
</indexterm>
|
|
<listitem>
|
|
<para>
|
|
When Hot Standby is active, this parameter determines how long the
|
|
standby server should wait before canceling standby queries that
|
|
conflict with about-to-be-applied WAL entries, as described in
|
|
<xref linkend="hot-standby-conflict">.
|
|
<varname>max_standby_archive_delay</> applies when WAL data is
|
|
being read from WAL archive (and is therefore not current).
|
|
The default is 30 seconds. Units are milliseconds if not specified.
|
|
A value of -1 allows the standby to wait forever for conflicting
|
|
queries to complete.
|
|
This parameter can only be set in the <filename>postgresql.conf</>
|
|
file or on the server command line.
|
|
</para>
|
|
<para>
|
|
Note that <varname>max_standby_archive_delay</> is not the same as the
|
|
maximum length of time a query can run before cancellation; rather it
|
|
is the maximum total time allowed to apply any one WAL segment's data.
|
|
Thus, if one query has resulted in significant delay earlier in the
|
|
WAL segment, subsequent conflicting queries will have much less grace
|
|
time.
|
|
</para>
|
|
</listitem>
|
|
</varlistentry>
|
|
|
|
<varlistentry id="guc-max-standby-streaming-delay" xreflabel="max_standby_streaming_delay">
|
|
<term><varname>max_standby_streaming_delay</varname> (<type>integer</type>)</term>
|
|
<indexterm>
|
|
<primary><varname>max_standby_streaming_delay</> configuration parameter</primary>
|
|
</indexterm>
|
|
<listitem>
|
|
<para>
|
|
When Hot Standby is active, this parameter determines how long the
|
|
standby server should wait before canceling standby queries that
|
|
conflict with about-to-be-applied WAL entries, as described in
|
|
<xref linkend="hot-standby-conflict">.
|
|
<varname>max_standby_streaming_delay</> applies when WAL data is
|
|
being received via streaming replication.
|
|
The default is 30 seconds. Units are milliseconds if not specified.
|
|
A value of -1 allows the standby to wait forever for conflicting
|
|
queries to complete.
|
|
This parameter can only be set in the <filename>postgresql.conf</>
|
|
file or on the server command line.
|
|
</para>
|
|
<para>
|
|
Note that <varname>max_standby_streaming_delay</> is not the same as
|
|
the maximum length of time a query can run before cancellation; rather
|
|
it is the maximum total time allowed to apply WAL data once it has
|
|
been received from the primary server. Thus, if one query has
|
|
resulted in significant delay, subsequent conflicting queries will
|
|
have much less grace time until the standby server has caught up
|
|
again.
|
|
</para>
|
|
</listitem>
|
|
</varlistentry>
|
|
|
|
<varlistentry id="guc-wal-receiver-status-interval" xreflabel="wal_receiver_status_interval">
|
|
<term><varname>wal_receiver_status_interval</varname> (<type>integer</type>)</term>
|
|
<indexterm>
|
|
<primary><varname>wal_receiver_status_interval</> configuration parameter</primary>
|
|
</indexterm>
|
|
<listitem>
|
|
<para>
|
|
Specifies the minimum frequency for the WAL receiver
|
|
process on the standby to send information about replication progress
|
|
to the primary or upstream standby, where it can be seen using the
|
|
<link linkend="monitoring-stats-views-table">
|
|
<literal>pg_stat_replication</></link> view. The standby will report
|
|
the last transaction log position it has written, the last position it
|
|
has flushed to disk, and the last position it has applied.
|
|
This parameter's
|
|
value is the maximum interval, in seconds, between reports. Updates are
|
|
sent each time the write or flush positions change, or at least as
|
|
often as specified by this parameter. Thus, the apply position may
|
|
lag slightly behind the true position. Setting this parameter to zero
|
|
disables status updates completely. This parameter can only be set in
|
|
the <filename>postgresql.conf</> file or on the server command line.
|
|
The default value is 10 seconds.
|
|
</para>
|
|
<para>
|
|
When <xref linkend="guc-replication-timeout"> is enabled on a sending server,
|
|
<varname>wal_receiver_status_interval</> must be enabled, and its value
|
|
must be less than the value of <varname>replication_timeout</>.
|
|
</para>
|
|
</listitem>
|
|
</varlistentry>
|
|
|
|
<varlistentry id="guc-hot-standby-feedback" xreflabel="hot_standby">
|
|
<term><varname>hot_standby_feedback</varname> (<type>boolean</type>)</term>
|
|
<indexterm>
|
|
<primary><varname>hot_standby_feedback</> configuration parameter</primary>
|
|
</indexterm>
|
|
<listitem>
|
|
<para>
|
|
Specifies whether or not a hot standby will send feedback to the primary
|
|
or upstream standby
|
|
about queries currently executing on the standby. This parameter can
|
|
be used to eliminate query cancels caused by cleanup records, but
|
|
can cause database bloat on the primary for some workloads.
|
|
Feedback messages will not be sent more frequently than once per
|
|
<varname>wal_receiver_status_interval</>. The default value is
|
|
<literal>off</literal>. This parameter can only be set in the
|
|
<filename>postgresql.conf</> file or on the server command line.
|
|
</para>
|
|
<para>
|
|
If cascaded replication is in use the feedback is passed upstream
|
|
until it eventually reaches the primary. Standbys make no other use
|
|
of feedback they receive other than to pass upstream.
|
|
</para>
|
|
</listitem>
|
|
</varlistentry>
|
|
|
|
</variablelist>
|
|
</sect2>
|
|
</sect1>
|
|
|
|
<sect1 id="runtime-config-query">
|
|
<title>Query Planning</title>
|
|
|
|
<sect2 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 <emphasis>temporary</> solution is to use one
|
|
of these configuration parameters to force the optimizer to
|
|
choose a different plan.
|
|
Better ways to improve the quality of the
|
|
plans chosen by the optimizer include adjusting the planer cost
|
|
constants (see <xref linkend="runtime-config-query-constants">),
|
|
running <xref linkend="sql-analyze"> manually, 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-bitmapscan" xreflabel="enable_bitmapscan">
|
|
<term><varname>enable_bitmapscan</varname> (<type>boolean</type>)</term>
|
|
<indexterm>
|
|
<primary>bitmap scan</primary>
|
|
</indexterm>
|
|
<indexterm>
|
|
<primary><varname>enable_bitmapscan</> configuration parameter</primary>
|
|
</indexterm>
|
|
<listitem>
|
|
<para>
|
|
Enables or disables the query planner's use of bitmap-scan plan
|
|
types. The default is <literal>on</>.
|
|
</para>
|
|
</listitem>
|
|
</varlistentry>
|
|
|
|
<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 <literal>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 <literal>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 <literal>on</>.
|
|
</para>
|
|
</listitem>
|
|
</varlistentry>
|
|
|
|
<varlistentry id="guc-enable-material" xreflabel="enable_material">
|
|
<term><varname>enable_material</varname> (<type>boolean</type>)</term>
|
|
<indexterm>
|
|
<primary><varname>enable_material</> configuration parameter</primary>
|
|
</indexterm>
|
|
<listitem>
|
|
<para>
|
|
Enables or disables the query planner's use of materialization.
|
|
It is impossible to suppress materialization entirely,
|
|
but turning this variable off prevents the planner from inserting
|
|
materialize nodes except in cases where it is required for correctness.
|
|
The default is <literal>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 <literal>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 is impossible 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
|
|
<literal>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 is impossible 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 <literal>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 is impossible 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 <literal>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 <literal>on</>.
|
|
</para>
|
|
</listitem>
|
|
</varlistentry>
|
|
|
|
</variablelist>
|
|
</sect2>
|
|
<sect2 id="runtime-config-query-constants">
|
|
<title>Planner Cost Constants</title>
|
|
|
|
<para>
|
|
The <firstterm>cost</> variables described in this section are measured
|
|
on an arbitrary scale. Only their relative values matter, hence
|
|
scaling them all up or down by the same factor will result in no change
|
|
in the planner's choices. By default, these cost variables are based on
|
|
the cost of sequential page fetches; that is,
|
|
<varname>seq_page_cost</> is conventionally set to <literal>1.0</>
|
|
and the other cost variables are set with reference to that. But
|
|
you can use a different scale if you prefer, such as actual execution
|
|
times in milliseconds on a particular machine.
|
|
</para>
|
|
|
|
<note>
|
|
<para>
|
|
Unfortunately, there is no well-defined method for determining ideal
|
|
values for the cost variables. They are best treated as averages over
|
|
the entire mix of queries that a particular installation will receive. This
|
|
means that changing them on the basis of just a few experiments is very
|
|
risky.
|
|
</para>
|
|
</note>
|
|
|
|
<variablelist>
|
|
|
|
<varlistentry id="guc-seq-page-cost" xreflabel="seq_page_cost">
|
|
<term><varname>seq_page_cost</varname> (<type>floating point</type>)</term>
|
|
<indexterm>
|
|
<primary><varname>seq_page_cost</> configuration parameter</primary>
|
|
</indexterm>
|
|
<listitem>
|
|
<para>
|
|
Sets the planner's estimate of the cost of a disk page fetch
|
|
that is part of a series of sequential fetches. The default is 1.0.
|
|
This value can be overridden for tables and indexes in a particular
|
|
tablespace by setting the tablespace parameter of the same name
|
|
(see <xref linkend="sql-altertablespace">).
|
|
</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
|
|
non-sequentially-fetched disk page. The default is 4.0.
|
|
This value can be overridden for tables and indexes in a particular
|
|
tablespace by setting the tablespace parameter of the same name
|
|
(see <xref linkend="sql-altertablespace">).
|
|
</para>
|
|
|
|
<para>
|
|
Reducing this value relative to <varname>seq_page_cost</>
|
|
will cause the system to prefer index scans; raising it will
|
|
make index scans look relatively more expensive. You can raise
|
|
or lower both values together to change the importance of disk I/O
|
|
costs relative to CPU costs, which are described by the following
|
|
parameters.
|
|
</para>
|
|
|
|
<tip>
|
|
<para>
|
|
Although the system will let you set <varname>random_page_cost</> to
|
|
less than <varname>seq_page_cost</>, it is not physically sensible
|
|
to do so. However, setting them equal makes sense if the database
|
|
is entirely cached in RAM, since in that case there is no penalty
|
|
for touching pages out of sequence. Also, in a heavily-cached
|
|
database you should lower both values relative to the CPU parameters,
|
|
since the cost of fetching a page already in RAM is much smaller
|
|
than it would normally be.
|
|
</para>
|
|
</tip>
|
|
</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.
|
|
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 entry during an index scan.
|
|
The default is 0.005.
|
|
</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 or function executed during a query.
|
|
The default is 0.0025.
|
|
</para>
|
|
</listitem>
|
|
</varlistentry>
|
|
|
|
<varlistentry id="guc-effective-cache-size" xreflabel="effective_cache_size">
|
|
<term><varname>effective_cache_size</varname> (<type>integer</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 query. 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 on different
|
|
tables, since they will have to share the available
|
|
space. This parameter has no effect on the size of shared
|
|
memory allocated by <productname>PostgreSQL</productname>, nor
|
|
does it reserve kernel disk cache; it is used only for estimation
|
|
purposes. The system also does not assume data remains in
|
|
the disk cache between queries. The default is 128 megabytes
|
|
(<literal>128MB</>).
|
|
</para>
|
|
</listitem>
|
|
</varlistentry>
|
|
|
|
</variablelist>
|
|
|
|
</sect2>
|
|
<sect2 id="runtime-config-query-geqo">
|
|
<title>Genetic Query Optimizer</title>
|
|
|
|
<para>
|
|
The genetic query optimizer (GEQO) is an algorithm that does query
|
|
planning using heuristic searching. This reduces planning time for
|
|
complex queries (those joining many relations), at the cost of producing
|
|
plans that are sometimes inferior to those found by the normal
|
|
exhaustive-search algorithm. Also, GEQO's searching is randomized and
|
|
therefore its plans may vary nondeterministically.
|
|
For more information see <xref linkend="geqo">.
|
|
</para>
|
|
|
|
<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.
|
|
This is on by default. It is usually best not to turn it off in
|
|
production; the <varname>geqo_threshold</varname> variable provides
|
|
more granular control of GEQO.
|
|
</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 a
|
|
<literal>FULL OUTER 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, often
|
|
longer than the penalty of executing a suboptimal plan.
|
|
</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
|
|
quality in GEQO. This variable must be an integer in the
|
|
range from 1 to 10. The default value is five. 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, that 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
|
|
value 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, that is
|
|
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 value 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>
|
|
|
|
<varlistentry id="guc-geqo-seed" xreflabel="geqo_seed">
|
|
<term><varname>geqo_seed</varname> (<type>floating point</type>)</term>
|
|
<indexterm>
|
|
<primary><varname>geqo_seed</> configuration parameter</primary>
|
|
</indexterm>
|
|
<listitem>
|
|
<para>
|
|
Controls the initial value of the random number generator used
|
|
by GEQO to select random paths through the join order search space.
|
|
The value can range from zero (the default) to one. Varying the
|
|
value changes the set of join paths explored, and may result in a
|
|
better or worse best path being found.
|
|
</para>
|
|
</listitem>
|
|
</varlistentry>
|
|
|
|
</variablelist>
|
|
</sect2>
|
|
<sect2 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 without
|
|
a column-specific target set via <command>ALTER TABLE
|
|
SET STATISTICS</>. Larger values increase the time needed to
|
|
do <command>ANALYZE</>, but might improve the quality of the
|
|
planner's estimates. The default is 100. 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-constraint-exclusion" xreflabel="constraint_exclusion">
|
|
<term><varname>constraint_exclusion</varname> (<type>enum</type>)</term>
|
|
<indexterm>
|
|
<primary>constraint exclusion</primary>
|
|
</indexterm>
|
|
<indexterm>
|
|
<primary><varname>constraint_exclusion</> configuration parameter</primary>
|
|
</indexterm>
|
|
<listitem>
|
|
<para>
|
|
Controls the query planner's use of table constraints to
|
|
optimize queries.
|
|
The allowed values of <varname>constraint_exclusion</> are
|
|
<literal>on</> (examine constraints for all tables),
|
|
<literal>off</> (never examine constraints), and
|
|
<literal>partition</> (examine constraints only for inheritance child
|
|
tables and <literal>UNION ALL</> subqueries).
|
|
<literal>partition</> is the default setting.
|
|
It is often used with inheritance and partitioned tables to
|
|
improve performance.
|
|
</para>
|
|
|
|
<para>
|
|
When this parameter allows it for a particular table, the planner
|
|
compares query conditions with the table's <literal>CHECK</>
|
|
constraints, and omits scanning tables for which the conditions
|
|
contradict the constraints. For example:
|
|
|
|
<programlisting>
|
|
CREATE TABLE parent(key integer, ...);
|
|
CREATE TABLE child1000(check (key between 1000 and 1999)) INHERITS(parent);
|
|
CREATE TABLE child2000(check (key between 2000 and 2999)) INHERITS(parent);
|
|
...
|
|
SELECT * FROM parent WHERE key = 2400;
|
|
</programlisting>
|
|
|
|
With constraint exclusion enabled, this <command>SELECT</>
|
|
will not scan <structname>child1000</> at all, improving performance.
|
|
</para>
|
|
|
|
<para>
|
|
Currently, constraint exclusion is enabled by default
|
|
only for cases that are often used to implement table partitioning.
|
|
Turning it on for all tables imposes extra planning overhead that is
|
|
quite noticeable on simple queries, and most often will yield no
|
|
benefit for simple queries. If you have no partitioned tables
|
|
you might prefer to turn it off entirely.
|
|
</para>
|
|
|
|
<para>
|
|
Refer to <xref linkend="ddl-partitioning-constraint-exclusion"> for
|
|
more information on using constraint exclusion and partitioning.
|
|
</para>
|
|
</listitem>
|
|
</varlistentry>
|
|
|
|
<varlistentry id="guc-cursor-tuple-fraction" xreflabel="cursor_tuple_fraction">
|
|
<term><varname>cursor_tuple_fraction</varname> (<type>floating point</type>)</term>
|
|
<indexterm>
|
|
<primary><varname>cursor_tuple_fraction</> configuration parameter</primary>
|
|
</indexterm>
|
|
<listitem>
|
|
<para>
|
|
Sets the planner's estimate of the fraction of a cursor's rows that
|
|
will be retrieved. The default is 0.1. Smaller values of this
|
|
setting bias the planner towards using <quote>fast start</> plans
|
|
for cursors, which will retrieve the first few rows quickly while
|
|
perhaps taking a long time to fetch all rows. Larger values
|
|
put more emphasis on the total estimated time. At the maximum
|
|
setting of 1.0, cursors are planned exactly like regular queries,
|
|
considering only the total estimated time and not how soon the
|
|
first rows might be delivered.
|
|
</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 might
|
|
yield inferior query plans. The default is eight.
|
|
For more information see <xref linkend="explicit-joins">.
|
|
</para>
|
|
|
|
<para>
|
|
Setting this value to <xref linkend="guc-geqo-threshold"> or more
|
|
may trigger use of the GEQO planner, resulting in nondeterministic
|
|
plans. See <xref linkend="runtime-config-query-geqo">.
|
|
</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 <literal>JOIN</>
|
|
constructs (except <literal>FULL JOIN</>s) into lists of
|
|
<literal>FROM</> items whenever a list of no more than this many items
|
|
would result. Smaller values reduce planning time but might
|
|
yield inferior query plans.
|
|
</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
|
|
explicit <literal>JOIN</>s. Thus, the explicit join order
|
|
specified in the query will be the actual order in which the
|
|
relations are joined. Because the query planner does not always choose
|
|
the optimal join order, advanced users can elect to
|
|
temporarily set this variable to 1, and then specify the join
|
|
order they desire explicitly.
|
|
For more information see <xref linkend="explicit-joins">.
|
|
</para>
|
|
|
|
<para>
|
|
Setting this value to <xref linkend="guc-geqo-threshold"> or more
|
|
may trigger use of the GEQO planner, resulting in nondeterministic
|
|
plans. See <xref linkend="runtime-config-query-geqo">.
|
|
</para>
|
|
</listitem>
|
|
</varlistentry>
|
|
|
|
</variablelist>
|
|
</sect2>
|
|
</sect1>
|
|
|
|
<sect1 id="runtime-config-logging">
|
|
<title>Error Reporting and Logging</title>
|
|
|
|
<indexterm zone="runtime-config-logging">
|
|
<primary>server log</primary>
|
|
</indexterm>
|
|
|
|
<sect2 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>, <systemitem>csvlog</systemitem> and
|
|
<systemitem>syslog</systemitem>. On Windows,
|
|
<systemitem>eventlog</systemitem> is also supported. Set this
|
|
parameter to a list of desired log destinations separated by
|
|
commas. The default is to log to <systemitem>stderr</systemitem>
|
|
only.
|
|
This parameter can only be set in the <filename>postgresql.conf</>
|
|
file or on the server command line.
|
|
</para>
|
|
<para>
|
|
If <systemitem>csvlog</> is included in <varname>log_destination</>,
|
|
log entries are output in <quote>comma separated
|
|
value</> (<acronym>CSV</>) format, which is convenient for
|
|
loading logs into programs.
|
|
See <xref linkend="runtime-config-logging-csvlog"> for details.
|
|
<varname>logging_collector</varname> must be enabled to generate
|
|
CSV-format log output.
|
|
</para>
|
|
|
|
<note>
|
|
<para>
|
|
On most Unix systems, you will need to alter the configuration of
|
|
your system's <application>syslog</application> daemon in order
|
|
to make use of the <systemitem>syslog</systemitem> option for
|
|
<varname>log_destination</>. <productname>PostgreSQL</productname>
|
|
can log to <application>syslog</application> facilities
|
|
<literal>LOCAL0</> through <literal>LOCAL7</> (see <xref
|
|
linkend="guc-syslog-facility">), but the default
|
|
<application>syslog</application> configuration on most platforms
|
|
will discard all such messages. You will need to add something like:
|
|
<programlisting>
|
|
local0.* /var/log/postgresql
|
|
</programlisting>
|
|
to the <application>syslog</application> daemon's configuration file
|
|
to make it work.
|
|
</para>
|
|
</note>
|
|
</listitem>
|
|
</varlistentry>
|
|
|
|
<varlistentry id="guc-logging-collector" xreflabel="logging_collector">
|
|
<term><varname>logging_collector</varname> (<type>boolean</type>)</term>
|
|
<indexterm>
|
|
<primary><varname>logging_collector</> configuration parameter</primary>
|
|
</indexterm>
|
|
<listitem>
|
|
<para>
|
|
This parameter captures plain and CSV-format log messages
|
|
sent to <application>stderr</> and redirects them into log files.
|
|
This approach is often more useful than
|
|
logging to <application>syslog</>, since some types of messages
|
|
might not appear in <application>syslog</> output (a common example
|
|
is dynamic-linker failure messages).
|
|
This parameter can only be set at server start.
|
|
</para>
|
|
|
|
<note>
|
|
<para>
|
|
The logging collector is designed to never lose messages. This means
|
|
that in case of extremely high load, server processes could be
|
|
blocked due to trying to send additional log messages when the
|
|
collector has fallen behind. In contrast, <application>syslog</>
|
|
prefers to drop messages if it cannot write them, which means it's
|
|
less reliable in those cases but it will not block the rest of the
|
|
system.
|
|
</para>
|
|
</note>
|
|
|
|
</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>logging_collector</> is enabled,
|
|
this parameter determines the directory in which log files will be created.
|
|
It can be specified as an absolute path, or relative to the
|
|
cluster data directory.
|
|
This parameter can only be set in the <filename>postgresql.conf</>
|
|
file or on the server command line.
|
|
</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>logging_collector</varname> is enabled,
|
|
this parameter 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. (Note that if there are
|
|
any time-zone-dependent <literal>%</literal>-escapes, the computation
|
|
is done in the zone specified
|
|
by <xref linkend="guc-log-timezone">.)
|
|
The supported <literal>%</literal>-escapes are similar to those
|
|
listed in the Open Group's <ulink
|
|
url="http://pubs.opengroup.org/onlinepubs/009695399/functions/strftime.html">strftime
|
|
</ulink> specification.
|
|
Note that the system's <systemitem>strftime</systemitem> is not used
|
|
directly, so platform-specific (nonstandard) extensions do not work.
|
|
</para>
|
|
<para>
|
|
If you specify a file name without escapes, you should plan to
|
|
use a log rotation utility to avoid eventually filling the
|
|
entire disk. In releases prior to 8.4, if
|
|
no <literal>%</literal> escapes were
|
|
present, <productname>PostgreSQL</productname> would append
|
|
the epoch of the new log file's creation time, but this is no
|
|
longer the case.
|
|
</para>
|
|
<para>
|
|
If CSV-format output is enabled in <varname>log_destination</>,
|
|
<literal>.csv</> will be appended to the timestamped
|
|
log file name to create the file name for CSV-format output.
|
|
(If <varname>log_filename</> ends in <literal>.log</>, the suffix is
|
|
replaced instead.)
|
|
In the case of the example above, the CSV
|
|
file name will be <literal>server_log.1093827753.csv</literal>.
|
|
</para>
|
|
<para>
|
|
This parameter can only be set in the <filename>postgresql.conf</>
|
|
file or on the server command line.
|
|
</para>
|
|
</listitem>
|
|
</varlistentry>
|
|
|
|
<varlistentry id="guc-log-file-mode" xreflabel="log_file_mode">
|
|
<term><varname>log_file_mode</varname> (<type>integer</type>)</term>
|
|
<indexterm>
|
|
<primary><varname>log_file_mode</> configuration parameter</primary>
|
|
</indexterm>
|
|
<listitem>
|
|
<para>
|
|
On Unix systems this parameter sets the permissions for log files
|
|
when <varname>logging_collector</varname> is enabled. (On Microsoft
|
|
Windows this parameter is ignored.)
|
|
The parameter value is expected to be a numeric mode
|
|
specified in the format 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>0600</>, meaning only the
|
|
server owner can read or write the log files. The other commonly
|
|
useful setting is <literal>0640</>, allowing members of the owner's
|
|
group to read the files. Note however that to make use of such a
|
|
setting, you'll need to alter <xref linkend="guc-log-directory"> to
|
|
store the files somewhere outside the cluster data directory. In
|
|
any case, it's unwise to make the log files world-readable, since
|
|
they might contain sensitive data.
|
|
</para>
|
|
<para>
|
|
This parameter can only be set in the <filename>postgresql.conf</>
|
|
file or on the server command line.
|
|
</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>logging_collector</varname> is enabled,
|
|
this parameter 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 parameter can only be set in the <filename>postgresql.conf</>
|
|
file or on the server command line.
|
|
</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>logging_collector</varname> is enabled,
|
|
this parameter 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 parameter can only be set in the <filename>postgresql.conf</>
|
|
file or on the server command line.
|
|
</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>logging_collector</varname> is enabled,
|
|
this parameter 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 off, pre-existing files will be appended to in
|
|
all cases. For example, using this setting 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 parameter can only be set in the <filename>postgresql.conf</>
|
|
file or on the server command line.
|
|
</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>on</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>on</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 might occur to select a file name
|
|
different from the hour's initial file name.
|
|
</para>
|
|
</listitem>
|
|
</varlistentry>
|
|
|
|
<varlistentry id="guc-syslog-facility" xreflabel="syslog_facility">
|
|
<term><varname>syslog_facility</varname> (<type>enum</type>)</term>
|
|
<indexterm>
|
|
<primary><varname>syslog_facility</> configuration parameter</primary>
|
|
</indexterm>
|
|
<listitem>
|
|
<para>
|
|
When logging to <application>syslog</> is enabled, this parameter
|
|
determines the <application>syslog</application>
|
|
<quote>facility</quote> to be used. You can 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 parameter can only be set in the <filename>postgresql.conf</>
|
|
file or on the server command line.
|
|
</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 parameter
|
|
determines the program name used to identify
|
|
<productname>PostgreSQL</productname> messages in
|
|
<application>syslog</application> logs. The default is
|
|
<literal>postgres</literal>.
|
|
This parameter can only be set in the <filename>postgresql.conf</>
|
|
file or on the server command line.
|
|
</para>
|
|
</listitem>
|
|
</varlistentry>
|
|
|
|
</variablelist>
|
|
</sect2>
|
|
<sect2 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>enum</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</>, <literal>ERROR</>, <literal>FATAL</>,
|
|
and <literal>PANIC</>. 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>enum</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>WARNING</>. 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-min-error-statement" xreflabel="log_min_error_statement">
|
|
<term><varname>log_min_error_statement</varname> (<type>enum</type>)</term>
|
|
<indexterm>
|
|
<primary><varname>log_min_error_statement</> configuration parameter</primary>
|
|
</indexterm>
|
|
<listitem>
|
|
<para>
|
|
Controls which SQL statements that cause an error
|
|
condition are recorded in the server log. The current
|
|
SQL statement is included in the log entry for any message of
|
|
the specified severity or higher.
|
|
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>LOG</literal>,
|
|
<literal>FATAL</literal>, and <literal>PANIC</literal>.
|
|
The default is <literal>ERROR</literal>, which means statements
|
|
causing errors, log messages, fatal errors, or panics will be logged.
|
|
To effectively turn off logging of failing statements,
|
|
set this parameter to <literal>PANIC</literal>.
|
|
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>
|
|
Causes the duration of each completed statement to be logged
|
|
if the statement ran for at least the specified number of
|
|
milliseconds. Setting this to zero prints all statement durations.
|
|
Minus-one (the default) disables logging statement durations.
|
|
For example, if you set it to <literal>250ms</literal>
|
|
then all SQL statements that run 250ms or longer will be
|
|
logged. Enabling this parameter can be helpful in tracking down
|
|
unoptimized queries in your applications.
|
|
Only superusers can change this setting.
|
|
</para>
|
|
|
|
<para>
|
|
For clients using extended query protocol, durations of the Parse,
|
|
Bind, and Execute steps are logged independently.
|
|
</para>
|
|
|
|
<note>
|
|
<para>
|
|
When using this option together with
|
|
<xref linkend="guc-log-statement">,
|
|
the text of statements that are logged because of
|
|
<varname>log_statement</> will not be repeated in the
|
|
duration log message.
|
|
If you are not using <application>syslog</>, it is recommended
|
|
that you log the PID or session ID using
|
|
<xref linkend="guc-log-line-prefix">
|
|
so that you can link the statement message to the later
|
|
duration message using the process ID or session ID.
|
|
</para>
|
|
</note>
|
|
</listitem>
|
|
</varlistentry>
|
|
|
|
</variablelist>
|
|
|
|
<para>
|
|
<xref linkend="runtime-config-severity-levels"> explains the message
|
|
severity levels used by <productname>PostgreSQL</>. If logging output
|
|
is sent to <systemitem>syslog</systemitem> or Windows'
|
|
<systemitem>eventlog</systemitem>, the severity levels are translated
|
|
as shown in the table.
|
|
</para>
|
|
|
|
<table id="runtime-config-severity-levels">
|
|
<title>Message Severity Levels</title>
|
|
<tgroup cols="4">
|
|
<thead>
|
|
<row>
|
|
<entry>Severity</entry>
|
|
<entry>Usage</entry>
|
|
<entry><systemitem>syslog</></entry>
|
|
<entry><systemitem>eventlog</></entry>
|
|
</row>
|
|
</thead>
|
|
|
|
<tbody>
|
|
<row>
|
|
<entry><literal>DEBUG1..DEBUG5</></entry>
|
|
<entry>Provides successively-more-detailed information for use by
|
|
developers.</entry>
|
|
<entry><literal>DEBUG</></entry>
|
|
<entry><literal>INFORMATION</></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry><literal>INFO</></entry>
|
|
<entry>Provides information implicitly requested by the user,
|
|
e.g., output from <command>VACUUM VERBOSE</>.</entry>
|
|
<entry><literal>INFO</></entry>
|
|
<entry><literal>INFORMATION</></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry><literal>NOTICE</></entry>
|
|
<entry>Provides information that might be helpful to users, e.g.,
|
|
notice of truncation of long identifiers.</entry>
|
|
<entry><literal>NOTICE</></entry>
|
|
<entry><literal>INFORMATION</></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry><literal>WARNING</></entry>
|
|
<entry>Provides warnings of likely problems, e.g., <command>COMMIT</>
|
|
outside a transaction block.</entry>
|
|
<entry><literal>NOTICE</></entry>
|
|
<entry><literal>WARNING</></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry><literal>ERROR</></entry>
|
|
<entry>Reports an error that caused the current command to
|
|
abort.</entry>
|
|
<entry><literal>WARNING</></entry>
|
|
<entry><literal>ERROR</></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry><literal>LOG</></entry>
|
|
<entry>Reports information of interest to administrators, e.g.,
|
|
checkpoint activity.</entry>
|
|
<entry><literal>INFO</></entry>
|
|
<entry><literal>INFORMATION</></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry><literal>FATAL</></entry>
|
|
<entry>Reports an error that caused the current session to
|
|
abort.</entry>
|
|
<entry><literal>ERR</></entry>
|
|
<entry><literal>ERROR</></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry><literal>PANIC</></entry>
|
|
<entry>Reports an error that caused all database sessions to abort.</entry>
|
|
<entry><literal>CRIT</></entry>
|
|
<entry><literal>ERROR</></entry>
|
|
</row>
|
|
</tbody>
|
|
</tgroup>
|
|
</table>
|
|
|
|
</sect2>
|
|
<sect2 id="runtime-config-logging-what">
|
|
<title>What To Log</title>
|
|
|
|
<variablelist>
|
|
|
|
<varlistentry id="guc-application-name" xreflabel="application_name">
|
|
<term><varname>application_name</varname> (<type>string</type>)</term>
|
|
<indexterm>
|
|
<primary><varname>application_name</> configuration parameter</primary>
|
|
</indexterm>
|
|
<listitem>
|
|
<para>
|
|
The <varname>application_name</varname> can be any string of less than
|
|
<symbol>NAMEDATALEN</> characters (64 characters in a standard build).
|
|
It is typically set by an application upon connection to the server.
|
|
The name will be displayed in the <structname>pg_stat_activity</> view
|
|
and included in CSV log entries. It can also be included in regular
|
|
log entries via the <xref linkend="guc-log-line-prefix"> parameter.
|
|
Only printable ASCII characters may be used in the
|
|
<varname>application_name</varname> value. Other characters will be
|
|
replaced with question marks (<literal>?</literal>).
|
|
</para>
|
|
</listitem>
|
|
</varlistentry>
|
|
|
|
<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>
|
|
<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>
|
|
<listitem>
|
|
<para>
|
|
These parameters enable various debugging output to be emitted.
|
|
When set, they print the resulting parse tree, the query rewriter
|
|
output, or the execution plan for each executed query.
|
|
These messages are emitted at <literal>LOG</> message level, so by
|
|
default they will appear in the server log but will not be sent to the
|
|
client. You can change that by adjusting
|
|
<xref linkend="guc-client-min-messages"> and/or
|
|
<xref linkend="guc-log-min-messages">.
|
|
These parameters are off by default.
|
|
</para>
|
|
</listitem>
|
|
</varlistentry>
|
|
|
|
<varlistentry>
|
|
<term><varname>debug_pretty_print</varname> (<type>boolean</type>)</term>
|
|
<indexterm>
|
|
<primary><varname>debug_pretty_print</> configuration parameter</primary>
|
|
</indexterm>
|
|
<listitem>
|
|
<para>
|
|
When set, <varname>debug_pretty_print</varname> indents the messages
|
|
produced by <varname>debug_print_parse</varname>,
|
|
<varname>debug_print_rewritten</varname>, or
|
|
<varname>debug_print_plan</varname>. This results in more readable
|
|
but much longer output than the <quote>compact</> format used when
|
|
it is off. It is on by default.
|
|
</para>
|
|
</listitem>
|
|
</varlistentry>
|
|
|
|
<varlistentry id="guc-log-checkpoints" xreflabel="log_checkpoints">
|
|
<term><varname>log_checkpoints</varname> (<type>boolean</type>)</term>
|
|
<indexterm>
|
|
<primary><varname>log_checkpoints</> configuration parameter</primary>
|
|
</indexterm>
|
|
<listitem>
|
|
<para>
|
|
Causes checkpoints and restartpoints to be logged in the server log.
|
|
Some statistics are included in the log messages, including the number
|
|
of buffers written and the time spent writing them.
|
|
This parameter can only be set in the <filename>postgresql.conf</>
|
|
file or on the server command line. The default is off.
|
|
</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>
|
|
Causes each attempted connection to the server to be logged,
|
|
as well as successful completion of client authentication.
|
|
This parameter cannot be changed after session start.
|
|
The default is off.
|
|
</para>
|
|
|
|
<note>
|
|
<para>
|
|
Some client programs, like <application>psql</>, attempt
|
|
to connect twice while determining if a password is required, so
|
|
duplicate <quote>connection received</> messages do not
|
|
necessarily indicate a problem.
|
|
</para>
|
|
</note>
|
|
</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 parameter cannot be changed after session start.
|
|
</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 to be logged.
|
|
The default is <literal>off</>.
|
|
Only superusers can change this setting.
|
|
</para>
|
|
|
|
<para>
|
|
For clients using extended query protocol, durations of the Parse,
|
|
Bind, and Execute steps are logged independently.
|
|
</para>
|
|
|
|
<note>
|
|
<para>
|
|
The difference between setting this option and setting
|
|
<xref linkend="guc-log-min-duration-statement"> to zero is that
|
|
exceeding <varname>log_min_duration_statement</> forces the text of
|
|
the query to be logged, but this option doesn't. Thus, if
|
|
<varname>log_duration</> is <literal>on</> and
|
|
<varname>log_min_duration_statement</> has a positive value, all
|
|
durations are logged but the query text is included only for
|
|
statements exceeding the threshold. This behavior can be useful for
|
|
gathering statistics in high-load installations.
|
|
</para>
|
|
</note>
|
|
</listitem>
|
|
</varlistentry>
|
|
|
|
<varlistentry id="guc-log-error-verbosity" xreflabel="log_error_verbosity">
|
|
<term><varname>log_error_verbosity</varname> (<type>enum</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. <literal>TERSE</> excludes
|
|
the logging of <literal>DETAIL</>, <literal>HINT</>,
|
|
<literal>QUERY</>, and <literal>CONTEXT</> error information.
|
|
<literal>VERBOSE</> output includes the <symbol>SQLSTATE</> error
|
|
code (see also <xref linkend="errcodes-appendix">) and the source code file name, function name,
|
|
and line number that generated the error.
|
|
Only superusers can change this setting.
|
|
</para>
|
|
</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 this parameter on 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 parameter can only be set in the <filename>postgresql.conf</>
|
|
file or on the server command line.
|
|
</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.
|
|
<literal>%</> characters begin <quote>escape sequences</>
|
|
that are replaced with status information as outlined below.
|
|
Unrecognized escapes are ignored. Other
|
|
characters are copied straight to the log line. Some escapes are
|
|
only recognized by session processes, and are ignored by
|
|
background processes such as the main server process.
|
|
This parameter can only be set in the <filename>postgresql.conf</>
|
|
file or on the server command line. The default is an empty string.
|
|
|
|
<informaltable>
|
|
<tgroup cols="3">
|
|
<thead>
|
|
<row>
|
|
<entry>Escape</entry>
|
|
<entry>Effect</entry>
|
|
<entry>Session only</entry>
|
|
</row>
|
|
</thead>
|
|
<tbody>
|
|
<row>
|
|
<entry><literal>%a</literal></entry>
|
|
<entry>Application name</entry>
|
|
<entry>yes</entry>
|
|
</row>
|
|
<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>%h</literal></entry>
|
|
<entry>Remote host name or IP address</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 without milliseconds</entry>
|
|
<entry>no</entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal>%m</literal></entry>
|
|
<entry>Time stamp with milliseconds</entry>
|
|
<entry>no</entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal>%i</literal></entry>
|
|
<entry>Command tag: type of session's current command</entry>
|
|
<entry>yes</entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal>%e</literal></entry>
|
|
<entry>SQLSTATE error code</entry>
|
|
<entry>no</entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal>%c</literal></entry>
|
|
<entry>Session ID: see below</entry>
|
|
<entry>no</entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal>%l</literal></entry>
|
|
<entry>Number of the log line for each session or process, starting at 1</entry>
|
|
<entry>no</entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal>%s</literal></entry>
|
|
<entry>Process start time stamp</entry>
|
|
<entry>no</entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal>%v</literal></entry>
|
|
<entry>Virtual transaction ID (backendID/localXID)</entry>
|
|
<entry>no</entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal>%x</literal></entry>
|
|
<entry>Transaction ID (0 if none is assigned)</entry>
|
|
<entry>no</entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal>%q</literal></entry>
|
|
<entry>Produces no 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>
|
|
|
|
The <literal>%c</> escape prints a quasi-unique session identifier,
|
|
consisting of two 4-byte hexadecimal numbers (without leading zeros)
|
|
separated by a dot. The numbers are the process start time and the
|
|
process ID, so <literal>%c</> can also be used as a space saving way
|
|
of printing those items. For example, to generate the session
|
|
identifier from <literal>pg_stat_activity</>, use this query:
|
|
<programlisting>
|
|
SELECT to_hex(EXTRACT(EPOCH FROM backend_start)::integer) || '.' ||
|
|
to_hex(procpid)
|
|
FROM pg_stat_activity;
|
|
</programlisting>
|
|
|
|
</para>
|
|
|
|
<tip>
|
|
<para>
|
|
If you set a nonempty value for <varname>log_line_prefix</>,
|
|
you should usually make its last character be a space, to provide
|
|
visual separation from the rest of the log line. A punctuation
|
|
character can be used too.
|
|
</para>
|
|
</tip>
|
|
|
|
<tip>
|
|
<para>
|
|
<application>Syslog</> produces its own
|
|
time stamp and process ID information, so you probably do not want to
|
|
include those escapes if you are logging to <application>syslog</>.
|
|
</para>
|
|
</tip>
|
|
</listitem>
|
|
</varlistentry>
|
|
|
|
<varlistentry id="guc-log-lock-waits" xreflabel="log_lock_waits">
|
|
<term><varname>log_lock_waits</varname> (<type>boolean</type>)</term>
|
|
<indexterm>
|
|
<primary><varname>log_lock_waits</> configuration parameter</primary>
|
|
</indexterm>
|
|
<listitem>
|
|
<para>
|
|
Controls whether a log message is produced when a session waits
|
|
longer than <xref linkend="guc-deadlock-timeout"> to acquire a
|
|
lock. This is useful in determining if lock waits are causing
|
|
poor performance. The default is <literal>off</>.
|
|
</para>
|
|
</listitem>
|
|
</varlistentry>
|
|
|
|
<varlistentry id="guc-log-statement" xreflabel="log_statement">
|
|
<term><varname>log_statement</varname> (<type>enum</type>)</term>
|
|
<indexterm>
|
|
<primary><varname>log_statement</> configuration parameter</primary>
|
|
</indexterm>
|
|
<listitem>
|
|
<para>
|
|
Controls which SQL statements are logged. Valid values are
|
|
<literal>none</> (off), <literal>ddl</>, <literal>mod</>, and
|
|
<literal>all</> (all statements). <literal>ddl</> logs all data definition
|
|
statements, such as <command>CREATE</>, <command>ALTER</>, and
|
|
<command>DROP</> statements. <literal>mod</> logs all
|
|
<literal>ddl</> statements, plus data-modifying statements
|
|
such as <command>INSERT</>,
|
|
<command>UPDATE</>, <command>DELETE</>, <command>TRUNCATE</>,
|
|
and <command>COPY FROM</>.
|
|
<command>PREPARE</>, <command>EXECUTE</>, and
|
|
<command>EXPLAIN ANALYZE</> statements are also logged if their
|
|
contained command is of an appropriate type. For clients using
|
|
extended query protocol, logging occurs when an Execute message
|
|
is received, and values of the Bind parameters are included
|
|
(with any embedded single-quote marks doubled).
|
|
</para>
|
|
|
|
<para>
|
|
The default is <literal>none</>. Only superusers can change this
|
|
setting.
|
|
</para>
|
|
|
|
<note>
|
|
<para>
|
|
Statements that contain simple syntax errors are not logged
|
|
even by the <varname>log_statement</> = <literal>all</> setting,
|
|
because the log message is emitted only after basic parsing has
|
|
been done to determine the statement type. In the case of extended
|
|
query protocol, this setting likewise does not log statements that
|
|
fail before the Execute phase (i.e., during parse analysis or
|
|
planning). Set <varname>log_min_error_statement</> to
|
|
<literal>ERROR</> (or lower) to log such statements.
|
|
</para>
|
|
</note>
|
|
</listitem>
|
|
</varlistentry>
|
|
|
|
<varlistentry id="guc-log-temp-files" xreflabel="log_temp_files">
|
|
<term><varname>log_temp_files</varname> (<type>integer</type>)</term>
|
|
<indexterm>
|
|
<primary><varname>log_temp_files</> configuration parameter</primary>
|
|
</indexterm>
|
|
<listitem>
|
|
<para>
|
|
Controls logging of temporary file names and sizes.
|
|
Temporary files can be
|
|
created for sorts, hashes, and temporary query results.
|
|
A log entry is made for each temporary file when it is deleted.
|
|
A value of zero logs all temporary file information, while positive
|
|
values log only files whose size is greater than or equal to
|
|
the specified number of kilobytes. The
|
|
default setting is -1, which disables such logging.
|
|
Only superusers can change this setting.
|
|
</para>
|
|
</listitem>
|
|
</varlistentry>
|
|
|
|
<varlistentry id="guc-log-timezone" xreflabel="log_timezone">
|
|
<term><varname>log_timezone</varname> (<type>string</type>)</term>
|
|
<indexterm>
|
|
<primary><varname>log_timezone</> configuration parameter</primary>
|
|
</indexterm>
|
|
<listitem>
|
|
<para>
|
|
Sets the time zone used for timestamps written in the server log.
|
|
Unlike <xref linkend="guc-timezone">, this value is cluster-wide,
|
|
so that all sessions will report timestamps consistently.
|
|
The built-in default is <literal>GMT</>, but that is typically
|
|
overridden in <filename>postgresql.conf</>; <application>initdb</>
|
|
will install a setting there corresponding to its system environment.
|
|
See <xref linkend="datatype-timezones"> for more information.
|
|
This parameter can only be set in the <filename>postgresql.conf</>
|
|
file or on the server command line.
|
|
</para>
|
|
</listitem>
|
|
</varlistentry>
|
|
|
|
</variablelist>
|
|
</sect2>
|
|
<sect2 id="runtime-config-logging-csvlog">
|
|
<title>Using CSV-Format Log Output</title>
|
|
|
|
<para>
|
|
Including <literal>csvlog</> in the <varname>log_destination</> list
|
|
provides a convenient way to import log files into a database table.
|
|
This option emits log lines in comma-separated-values
|
|
(<acronym>CSV</>) format,
|
|
with these columns:
|
|
time stamp with milliseconds,
|
|
user name,
|
|
database name,
|
|
process ID,
|
|
client host:port number,
|
|
session ID,
|
|
per-session line number,
|
|
command tag,
|
|
session start time,
|
|
virtual transaction ID,
|
|
regular transaction ID,
|
|
error severity,
|
|
SQLSTATE code,
|
|
error message,
|
|
error message detail,
|
|
hint,
|
|
internal query that led to the error (if any),
|
|
character count of the error position therein,
|
|
error context,
|
|
user query that led to the error (if any and enabled by
|
|
<varname>log_min_error_statement</>),
|
|
character count of the error position therein,
|
|
location of the error in the PostgreSQL source code
|
|
(if <varname>log_error_verbosity</> is set to <literal>verbose</>),
|
|
and application name.
|
|
Here is a sample table definition for storing CSV-format log output:
|
|
|
|
<programlisting>
|
|
CREATE TABLE postgres_log
|
|
(
|
|
log_time timestamp(3) with time zone,
|
|
user_name text,
|
|
database_name text,
|
|
process_id integer,
|
|
connection_from text,
|
|
session_id text,
|
|
session_line_num bigint,
|
|
command_tag text,
|
|
session_start_time timestamp with time zone,
|
|
virtual_transaction_id text,
|
|
transaction_id bigint,
|
|
error_severity text,
|
|
sql_state_code text,
|
|
message text,
|
|
detail text,
|
|
hint text,
|
|
internal_query text,
|
|
internal_query_pos integer,
|
|
context text,
|
|
query text,
|
|
query_pos integer,
|
|
location text,
|
|
application_name text,
|
|
PRIMARY KEY (session_id, session_line_num)
|
|
);
|
|
</programlisting>
|
|
</para>
|
|
|
|
<para>
|
|
To import a log file into this table, use the <command>COPY FROM</>
|
|
command:
|
|
|
|
<programlisting>
|
|
COPY postgres_log FROM '/full/path/to/logfile.csv' WITH csv;
|
|
</programlisting>
|
|
</para>
|
|
|
|
<para>
|
|
There are a few things you need to do to simplify importing CSV log
|
|
files:
|
|
|
|
<orderedlist>
|
|
<listitem>
|
|
<para>
|
|
Set <varname>log_filename</varname> and
|
|
<varname>log_rotation_age</> to provide a consistent,
|
|
predictable naming scheme for your log files. This lets you
|
|
predict what the file name will be and know when an individual log
|
|
file is complete and therefore ready to be imported.
|
|
</para>
|
|
</listitem>
|
|
|
|
<listitem>
|
|
<para>
|
|
Set <varname>log_rotation_size</varname> to 0 to disable
|
|
size-based log rotation, as it makes the log file name difficult
|
|
to predict.
|
|
</para>
|
|
</listitem>
|
|
|
|
<listitem>
|
|
<para>
|
|
Set <varname>log_truncate_on_rotation</varname> to <literal>on</> so
|
|
that old log data isn't mixed with the new in the same file.
|
|
</para>
|
|
</listitem>
|
|
|
|
<listitem>
|
|
<para>
|
|
The table definition above includes a primary key specification.
|
|
This is useful to protect against accidentally importing the same
|
|
information twice. The <command>COPY</> command commits all of the
|
|
data it imports at one time, so any error will cause the entire
|
|
import to fail. If you import a partial log file and later import
|
|
the file again when it is complete, the primary key violation will
|
|
cause the import to fail. Wait until the log is complete and
|
|
closed before importing. This procedure will also protect against
|
|
accidentally importing a partial line that hasn't been completely
|
|
written, which would also cause <command>COPY</> to fail.
|
|
</para>
|
|
</listitem>
|
|
</orderedlist>
|
|
</para>
|
|
|
|
</sect2>
|
|
</sect1>
|
|
|
|
<sect1 id="runtime-config-statistics">
|
|
<title>Run-time Statistics</title>
|
|
|
|
<sect2 id="runtime-config-statistics-collector">
|
|
<title>Query and Index Statistics Collector</title>
|
|
|
|
<para>
|
|
These parameters control server-wide statistics collection features.
|
|
When statistics collection 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>
|
|
|
|
<variablelist>
|
|
|
|
<varlistentry id="guc-track-activities" xreflabel="track_activities">
|
|
<term><varname>track_activities</varname> (<type>boolean</type>)</term>
|
|
<indexterm>
|
|
<primary><varname>track_activities</> configuration parameter</primary>
|
|
</indexterm>
|
|
<listitem>
|
|
<para>
|
|
Enables the collection of information on the currently
|
|
executing command of each session, along with the time when
|
|
that command began execution. This parameter is on 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.
|
|
Only superusers can change this setting.
|
|
</para>
|
|
</listitem>
|
|
</varlistentry>
|
|
|
|
<varlistentry id="guc-track-activity-query-size" xreflabel="track_activity_query_size">
|
|
<term><varname>track_activity_query_size</varname> (<type>integer</type>)</term>
|
|
<indexterm>
|
|
<primary><varname>track_activity_query_size</> configuration parameter</primary>
|
|
</indexterm>
|
|
<listitem>
|
|
<para>
|
|
Specifies the number of bytes reserved to track the currently
|
|
executing command for each active session, for the
|
|
<structname>pg_stat_activity</>.<structfield>current_query</> field.
|
|
The default value is 1024. This parameter can only be set at server
|
|
start.
|
|
</para>
|
|
</listitem>
|
|
</varlistentry>
|
|
|
|
<varlistentry id="guc-track-counts" xreflabel="track_counts">
|
|
<term><varname>track_counts</varname> (<type>boolean</type>)</term>
|
|
<indexterm>
|
|
<primary><varname>track_counts</> configuration parameter</primary>
|
|
</indexterm>
|
|
<listitem>
|
|
<para>
|
|
Enables collection of statistics on database activity.
|
|
This parameter is on by default, because the autovacuum
|
|
daemon needs the collected information.
|
|
Only superusers can change this setting.
|
|
</para>
|
|
</listitem>
|
|
</varlistentry>
|
|
|
|
<varlistentry id="guc-track-functions" xreflabel="track_functions">
|
|
<term><varname>track_functions</varname> (<type>enum</type>)</term>
|
|
<indexterm>
|
|
<primary><varname>track_functions</> configuration parameter</primary>
|
|
</indexterm>
|
|
<listitem>
|
|
<para>
|
|
Enables tracking of function call counts and time used. Specify
|
|
<literal>pl</literal> to track only procedural-language functions,
|
|
<literal>all</literal> to also track SQL and C language functions.
|
|
The default is <literal>none</literal>, which disables function
|
|
statistics tracking. Only superusers can change this setting.
|
|
</para>
|
|
|
|
<note>
|
|
<para>
|
|
SQL-language functions that are simple enough to be <quote>inlined</>
|
|
into the calling query will not be tracked, regardless of this
|
|
setting.
|
|
</para>
|
|
</note>
|
|
</listitem>
|
|
</varlistentry>
|
|
|
|
<varlistentry id="guc-update-process-title" xreflabel="update_process_title">
|
|
<term><varname>update_process_title</varname> (<type>boolean</type>)</term>
|
|
<indexterm>
|
|
<primary><varname>update_process_title</> configuration parameter</primary>
|
|
</indexterm>
|
|
<listitem>
|
|
<para>
|
|
Enables updating of the process title every time a new SQL command
|
|
is received by the server. The process title is typically viewed
|
|
by the <command>ps</> command,
|
|
or in Windows by using the <application>Process Explorer</>.
|
|
Only superusers can change this setting.
|
|
</para>
|
|
</listitem>
|
|
</varlistentry>
|
|
|
|
<varlistentry id="guc-stats-temp-directory" xreflabel="stats_temp_directory">
|
|
<term><varname>stats_temp_directory</varname> (<type>string</type>)</term>
|
|
<indexterm>
|
|
<primary><varname>stats_temp_directory</> configuration parameter</primary>
|
|
</indexterm>
|
|
<listitem>
|
|
<para>
|
|
Sets the directory to store temporary statistics data in. This can be
|
|
a path relative to the data directory or an absolute path. The default
|
|
is <filename>pg_stat_tmp</filename>. Pointing this at a RAM-based
|
|
file system will decrease physical I/O requirements and can lead to
|
|
improved performance.
|
|
This parameter can only be set in the <filename>postgresql.conf</>
|
|
file or on the server command line.
|
|
</para>
|
|
</listitem>
|
|
</varlistentry>
|
|
|
|
</variablelist>
|
|
</sect2>
|
|
|
|
<sect2 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, output performance statistics of the respective
|
|
module to the server log. This is a crude profiling
|
|
instrument, similar to the Unix <function>getrusage()</> operating
|
|
system facility. <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>
|
|
|
|
</sect2>
|
|
</sect1>
|
|
|
|
<sect1 id="runtime-config-autovacuum">
|
|
<title>Automatic Vacuuming</title>
|
|
|
|
<indexterm>
|
|
<primary>autovacuum</primary>
|
|
<secondary>configuration parameters</secondary>
|
|
</indexterm>
|
|
|
|
<para>
|
|
These settings control the behavior of the <firstterm>autovacuum</>
|
|
feature. Refer to <xref linkend="autovacuum"> for
|
|
more information.
|
|
</para>
|
|
|
|
<variablelist>
|
|
|
|
<varlistentry id="guc-autovacuum" xreflabel="autovacuum">
|
|
<term><varname>autovacuum</varname> (<type>boolean</type>)</term>
|
|
<indexterm>
|
|
<primary><varname>autovacuum</> configuration parameter</primary>
|
|
</indexterm>
|
|
<listitem>
|
|
<para>
|
|
Controls whether the server should run the
|
|
autovacuum launcher daemon. This is on by default; however,
|
|
<xref linkend="guc-track-counts"> must also be enabled for
|
|
autovacuum to work.
|
|
This parameter can only be set in the <filename>postgresql.conf</>
|
|
file or on the server command line.
|
|
</para>
|
|
<para>
|
|
Note that even when this parameter is disabled, the system
|
|
will launch autovacuum processes if necessary to
|
|
prevent transaction ID wraparound. See <xref
|
|
linkend="vacuum-for-wraparound"> for more information.
|
|
</para>
|
|
</listitem>
|
|
</varlistentry>
|
|
|
|
<varlistentry id="guc-log-autovacuum-min-duration" xreflabel="log_autovacuum_min_duration">
|
|
<term><varname>log_autovacuum_min_duration</varname> (<type>integer</type>)</term>
|
|
<indexterm>
|
|
<primary><varname>log_autovacuum_min_duration</> configuration parameter</primary>
|
|
</indexterm>
|
|
<listitem>
|
|
<para>
|
|
Causes each action executed by autovacuum to be logged if it ran for at
|
|
least the specified number of milliseconds. Setting this to zero logs
|
|
all autovacuum actions. Minus-one (the default) disables logging
|
|
autovacuum actions. For example, if you set this to
|
|
<literal>250ms</literal> then all automatic vacuums and analyzes that run
|
|
250ms or longer will be logged. In addition, when this parameter is
|
|
set to any value other than <literal>-1</literal>, a message will be
|
|
logged if an autovacuum action is skipped due to the existence of a
|
|
conflicting lock. Enabling this parameter can be helpful
|
|
in tracking autovacuum activity. This setting can only be set in
|
|
the <filename>postgresql.conf</> file or on the server command line.
|
|
</para>
|
|
</listitem>
|
|
</varlistentry>
|
|
|
|
<varlistentry id="guc-autovacuum-max-workers" xreflabel="autovacuum_max_workers">
|
|
<term><varname>autovacuum_max_workers</varname> (<type>integer</type>)</term>
|
|
<indexterm>
|
|
<primary><varname>autovacuum_max_workers</> configuration parameter</primary>
|
|
</indexterm>
|
|
<listitem>
|
|
<para>
|
|
Specifies the maximum number of autovacuum processes (other than the
|
|
autovacuum launcher) which may be running at any one time. The default
|
|
is three. This parameter can only be set at server start.
|
|
</para>
|
|
</listitem>
|
|
</varlistentry>
|
|
|
|
<varlistentry id="guc-autovacuum-naptime" xreflabel="autovacuum_naptime">
|
|
<term><varname>autovacuum_naptime</varname> (<type>integer</type>)</term>
|
|
<indexterm>
|
|
<primary><varname>autovacuum_naptime</> configuration parameter</primary>
|
|
</indexterm>
|
|
<listitem>
|
|
<para>
|
|
Specifies the minimum delay between autovacuum runs on any given
|
|
database. In each round the daemon examines the
|
|
database and issues <command>VACUUM</> and <command>ANALYZE</> commands
|
|
as needed for tables in that database. The delay is measured
|
|
in seconds, and the default is one minute (<literal>1min</>).
|
|
This parameter can only be set in the <filename>postgresql.conf</>
|
|
file or on the server command line.
|
|
</para>
|
|
</listitem>
|
|
</varlistentry>
|
|
|
|
<varlistentry id="guc-autovacuum-vacuum-threshold" xreflabel="autovacuum_vacuum_threshold">
|
|
<term><varname>autovacuum_vacuum_threshold</varname> (<type>integer</type>)</term>
|
|
<indexterm>
|
|
<primary><varname>autovacuum_vacuum_threshold</> configuration parameter</primary>
|
|
</indexterm>
|
|
<listitem>
|
|
<para>
|
|
Specifies the minimum number of updated or deleted tuples needed
|
|
to trigger a <command>VACUUM</> in any one table.
|
|
The default is 50 tuples.
|
|
This parameter can only be set in the <filename>postgresql.conf</>
|
|
file or on the server command line.
|
|
This setting can be overridden for individual tables by
|
|
changing storage parameters.
|
|
</para>
|
|
</listitem>
|
|
</varlistentry>
|
|
|
|
<varlistentry id="guc-autovacuum-analyze-threshold" xreflabel="autovacuum_analyze_threshold">
|
|
<term><varname>autovacuum_analyze_threshold</varname> (<type>integer</type>)</term>
|
|
<indexterm>
|
|
<primary><varname>autovacuum_analyze_threshold</> configuration parameter</primary>
|
|
</indexterm>
|
|
<listitem>
|
|
<para>
|
|
Specifies the minimum number of inserted, updated or deleted tuples
|
|
needed to trigger an <command>ANALYZE</> in any one table.
|
|
The default is 50 tuples.
|
|
This parameter can only be set in the <filename>postgresql.conf</>
|
|
file or on the server command line.
|
|
This setting can be overridden for individual tables by
|
|
changing storage parameters.
|
|
</para>
|
|
</listitem>
|
|
</varlistentry>
|
|
|
|
<varlistentry id="guc-autovacuum-vacuum-scale-factor" xreflabel="autovacuum_vacuum_scale_factor">
|
|
<term><varname>autovacuum_vacuum_scale_factor</varname> (<type>floating point</type>)</term>
|
|
<indexterm>
|
|
<primary><varname>autovacuum_vacuum_scale_factor</> configuration parameter</primary>
|
|
</indexterm>
|
|
<listitem>
|
|
<para>
|
|
Specifies a fraction of the table size to add to
|
|
<varname>autovacuum_vacuum_threshold</varname>
|
|
when deciding whether to trigger a <command>VACUUM</>.
|
|
The default is 0.2 (20% of table size).
|
|
This parameter can only be set in the <filename>postgresql.conf</>
|
|
file or on the server command line.
|
|
This setting can be overridden for individual tables by
|
|
changing storage parameters.
|
|
</para>
|
|
</listitem>
|
|
</varlistentry>
|
|
|
|
<varlistentry id="guc-autovacuum-analyze-scale-factor" xreflabel="autovacuum_analyze_scale_factor">
|
|
<term><varname>autovacuum_analyze_scale_factor</varname> (<type>floating point</type>)</term>
|
|
<indexterm>
|
|
<primary><varname>autovacuum_analyze_scale_factor</> configuration parameter</primary>
|
|
</indexterm>
|
|
<listitem>
|
|
<para>
|
|
Specifies a fraction of the table size to add to
|
|
<varname>autovacuum_analyze_threshold</varname>
|
|
when deciding whether to trigger an <command>ANALYZE</>.
|
|
The default is 0.1 (10% of table size).
|
|
This parameter can only be set in the <filename>postgresql.conf</>
|
|
file or on the server command line.
|
|
This setting can be overridden for individual tables by
|
|
changing storage parameters.
|
|
</para>
|
|
</listitem>
|
|
</varlistentry>
|
|
|
|
<varlistentry id="guc-autovacuum-freeze-max-age" xreflabel="autovacuum_freeze_max_age">
|
|
<term><varname>autovacuum_freeze_max_age</varname> (<type>integer</type>)</term>
|
|
<indexterm>
|
|
<primary><varname>autovacuum_freeze_max_age</> configuration parameter</primary>
|
|
</indexterm>
|
|
<listitem>
|
|
<para>
|
|
Specifies the maximum age (in transactions) that a table's
|
|
<structname>pg_class</>.<structfield>relfrozenxid</> field can
|
|
attain before a <command>VACUUM</> operation is forced
|
|
to prevent transaction ID wraparound within the table.
|
|
Note that the system will launch autovacuum processes to
|
|
prevent wraparound even when autovacuum is otherwise disabled.
|
|
</para>
|
|
|
|
<para>
|
|
Vacuum also allows removal of old files from the
|
|
<filename>pg_clog</> subdirectory, which is why the default
|
|
is a relatively low 200 million transactions.
|
|
This parameter can only be set at server start, but the setting
|
|
can be reduced for individual tables by
|
|
changing storage parameters.
|
|
For more information see <xref linkend="vacuum-for-wraparound">.
|
|
</para>
|
|
</listitem>
|
|
</varlistentry>
|
|
|
|
<varlistentry id="guc-autovacuum-vacuum-cost-delay" xreflabel="autovacuum_vacuum_cost_delay">
|
|
<term><varname>autovacuum_vacuum_cost_delay</varname> (<type>integer</type>)</term>
|
|
<indexterm>
|
|
<primary><varname>autovacuum_vacuum_cost_delay</> configuration parameter</primary>
|
|
</indexterm>
|
|
<listitem>
|
|
<para>
|
|
Specifies the cost delay value that will be used in automatic
|
|
<command>VACUUM</> operations. If -1 is specified, the regular
|
|
<xref linkend="guc-vacuum-cost-delay"> value will be used.
|
|
The default value is 20 milliseconds.
|
|
This parameter can only be set in the <filename>postgresql.conf</>
|
|
file or on the server command line.
|
|
This setting can be overridden for individual tables by
|
|
changing storage parameters.
|
|
</para>
|
|
</listitem>
|
|
</varlistentry>
|
|
|
|
<varlistentry id="guc-autovacuum-vacuum-cost-limit" xreflabel="autovacuum_vacuum_cost_limit">
|
|
<term><varname>autovacuum_vacuum_cost_limit</varname> (<type>integer</type>)</term>
|
|
<indexterm>
|
|
<primary><varname>autovacuum_vacuum_cost_limit</> configuration parameter</primary>
|
|
</indexterm>
|
|
<listitem>
|
|
<para>
|
|
Specifies the cost limit value that will be used in automatic
|
|
<command>VACUUM</> operations. If -1 is specified (which is the
|
|
default), the regular
|
|
<xref linkend="guc-vacuum-cost-limit"> value will be used. Note that
|
|
the value is distributed proportionally among the running autovacuum
|
|
workers, if there is more than one, so that the sum of the limits of
|
|
each worker never exceeds the limit on this variable.
|
|
This parameter can only be set in the <filename>postgresql.conf</>
|
|
file or on the server command line.
|
|
This setting can be overridden for individual tables by
|
|
changing storage parameters.
|
|
</para>
|
|
</listitem>
|
|
</varlistentry>
|
|
|
|
</variablelist>
|
|
</sect1>
|
|
|
|
<sect1 id="runtime-config-client">
|
|
<title>Client Connection Defaults</title>
|
|
|
|
<sect2 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 specified. 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> must 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.
|
|
</para>
|
|
|
|
<para>
|
|
Likewise, the current session's temporary-table schema,
|
|
<literal>pg_temp_<replaceable>nnn</></>, is always searched if it
|
|
exists. It can be explicitly listed in the path by using the
|
|
alias <literal>pg_temp</>. If it is not listed in the path then
|
|
it is searched first (even before <literal>pg_catalog</>). However,
|
|
the temporary schema is only searched for relation (table, view,
|
|
sequence, etc) and data type names. It is never searched for
|
|
function or operator names.
|
|
</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</>
|
|
(see <xref linkend="functions-info">).
|
|
This is not quite the same as
|
|
examining the value of <varname>search_path</varname>, since
|
|
<function>current_schemas</> shows how the items
|
|
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. If a nondefault tablespace
|
|
is specified, the user must have <literal>CREATE</> privilege
|
|
for it, or creation attempts will fail.
|
|
</para>
|
|
|
|
<para>
|
|
This variable is not used for temporary tables; for them,
|
|
<xref linkend="guc-temp-tablespaces"> is consulted instead.
|
|
</para>
|
|
|
|
<para>
|
|
This variable is also not used when creating databases.
|
|
By default, a new database inherits its tablespace setting from
|
|
the template database it is copied from.
|
|
</para>
|
|
|
|
<para>
|
|
For more information on tablespaces,
|
|
see <xref linkend="manage-ag-tablespaces">.
|
|
</para>
|
|
</listitem>
|
|
</varlistentry>
|
|
|
|
<varlistentry id="guc-temp-tablespaces" xreflabel="temp_tablespaces">
|
|
<term><varname>temp_tablespaces</varname> (<type>string</type>)</term>
|
|
<indexterm>
|
|
<primary><varname>temp_tablespaces</> configuration parameter</primary>
|
|
</indexterm>
|
|
<indexterm><primary>tablespace</><secondary>temporary</></>
|
|
<listitem>
|
|
<para>
|
|
This variable specifies tablespaces in which to create temporary
|
|
objects (temp tables and indexes on temp tables) when a
|
|
<command>CREATE</> command does not explicitly specify a tablespace.
|
|
Temporary files for purposes such as sorting large data sets
|
|
are also created in these tablespaces.
|
|
</para>
|
|
|
|
<para>
|
|
The value is a list of names of tablespaces. When there is more than
|
|
one name in the list, <productname>PostgreSQL</> chooses a random
|
|
member of the list each time a temporary object is to be created;
|
|
except that within a transaction, successively created temporary
|
|
objects are placed in successive tablespaces from the list.
|
|
If the selected element of the list is an empty string,
|
|
<productname>PostgreSQL</> will automatically use the default
|
|
tablespace of the current database instead.
|
|
</para>
|
|
|
|
<para>
|
|
When <varname>temp_tablespaces</> is set interactively, specifying a
|
|
nonexistent tablespace is an error, as is specifying a tablespace for
|
|
which the user does not have <literal>CREATE</> privilege. However,
|
|
when using a previously set value, nonexistent tablespaces are
|
|
ignored, as are tablespaces for which the user lacks
|
|
<literal>CREATE</> privilege. In particular, this rule applies when
|
|
using a value set in <filename>postgresql.conf</>.
|
|
</para>
|
|
|
|
<para>
|
|
The default value is an empty string, which results in all temporary
|
|
objects being created in the default tablespace of the current
|
|
database.
|
|
</para>
|
|
|
|
<para>
|
|
See also <xref linkend="guc-default-tablespace">.
|
|
</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 on. When set to <literal>off</>, it
|
|
disables validation of the function body string during <xref
|
|
linkend="sql-createfunction">. 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>
|
|
<secondary>setting default</secondary>
|
|
</indexterm>
|
|
<indexterm>
|
|
<primary><varname>default_transaction_isolation</> configuration parameter</primary>
|
|
</indexterm>
|
|
<term><varname>default_transaction_isolation</varname> (<type>enum</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>
|
|
<secondary>setting default</secondary>
|
|
</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 <literal>off</> (read/write).
|
|
</para>
|
|
|
|
<para>
|
|
Consult <xref linkend="sql-set-transaction"> for more information.
|
|
</para>
|
|
</listitem>
|
|
</varlistentry>
|
|
|
|
<varlistentry id="guc-default-transaction-deferrable" xreflabel="default_transaction_deferrable">
|
|
<indexterm>
|
|
<primary>deferrable transaction</primary>
|
|
<secondary>setting default</secondary>
|
|
</indexterm>
|
|
<indexterm>
|
|
<primary><varname>default_transaction_deferrable</> configuration parameter</primary>
|
|
</indexterm>
|
|
|
|
<term><varname>default_transaction_deferrable</varname> (<type>boolean</type>)</term>
|
|
<listitem>
|
|
<para>
|
|
When running at the <literal>serializable</> isolation level,
|
|
a deferrable read-only SQL transaction may be delayed before
|
|
it is allowed to proceed. However, once it begins executing
|
|
it does not incur any of the overhead required to ensure
|
|
serializability; so serialization code will have no reason to
|
|
force it to abort because of concurrent updates, making this
|
|
option suitable for long-running read-only transactions.
|
|
</para>
|
|
|
|
<para>
|
|
This parameter controls the default deferrable status of each
|
|
new transaction. It currently has no effect on read-write
|
|
transactions or those operating at isolation levels lower
|
|
than <literal>serializable</>. The default is <literal>off</>.
|
|
</para>
|
|
|
|
<para>
|
|
Consult <xref linkend="sql-set-transaction"> for more information.
|
|
</para>
|
|
</listitem>
|
|
</varlistentry>
|
|
|
|
|
|
<varlistentry id="guc-session-replication-role" xreflabel="session_replication_role">
|
|
<term><varname>session_replication_role</varname> (<type>enum</type>)</term>
|
|
<indexterm>
|
|
<primary><varname>session_replication_role</> configuration parameter</primary>
|
|
</indexterm>
|
|
<listitem>
|
|
<para>
|
|
Controls firing of replication-related triggers and rules for the
|
|
current session. Setting this variable requires
|
|
superuser privilege and results in discarding any previously cached
|
|
query plans. Possible values are <literal>origin</> (the default),
|
|
<literal>replica</> and <literal>local</>.
|
|
See <xref linkend="sql-altertable"> 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, starting from the time the command arrives at the server
|
|
from the client. If <varname>log_min_error_statement</> is set to
|
|
<literal>ERROR</> or lower, the statement that timed out will also be
|
|
logged. A value of zero (the default) turns this off.
|
|
</para>
|
|
|
|
<para>
|
|
Setting <varname>statement_timeout</> in
|
|
<filename>postgresql.conf</> is not recommended because it
|
|
affects all sessions.
|
|
</para>
|
|
</listitem>
|
|
</varlistentry>
|
|
|
|
<varlistentry id="guc-vacuum-freeze-table-age" xreflabel="vacuum_freeze_table_age">
|
|
<term><varname>vacuum_freeze_table_age</varname> (<type>integer</type>)</term>
|
|
<indexterm>
|
|
<primary><varname>vacuum_freeze_table_age</> configuration parameter</primary>
|
|
</indexterm>
|
|
<listitem>
|
|
<para>
|
|
<command>VACUUM</> performs a whole-table scan if the table's
|
|
<structname>pg_class</>.<structfield>relfrozenxid</> field has reached
|
|
the age specified by this setting. The default is 150 million
|
|
transactions. Although users can set this value anywhere from zero to
|
|
one billion, <command>VACUUM</> will silently limit the effective value
|
|
to 95% of <xref linkend="guc-autovacuum-freeze-max-age">, so that a
|
|
periodical manual <command>VACUUM</> has a chance to run before an
|
|
anti-wraparound autovacuum is launched for the table. For more
|
|
information see
|
|
<xref linkend="vacuum-for-wraparound">.
|
|
</para>
|
|
</listitem>
|
|
</varlistentry>
|
|
|
|
<varlistentry id="guc-vacuum-freeze-min-age" xreflabel="vacuum_freeze_min_age">
|
|
<term><varname>vacuum_freeze_min_age</varname> (<type>integer</type>)</term>
|
|
<indexterm>
|
|
<primary><varname>vacuum_freeze_min_age</> configuration parameter</primary>
|
|
</indexterm>
|
|
<listitem>
|
|
<para>
|
|
Specifies the cutoff age (in transactions) that <command>VACUUM</>
|
|
should use to decide whether to replace transaction IDs with
|
|
<literal>FrozenXID</> while scanning a table.
|
|
The default is 50 million transactions. Although
|
|
users can set this value anywhere from zero to one billion,
|
|
<command>VACUUM</> will silently limit the effective value to half
|
|
the value of <xref linkend="guc-autovacuum-freeze-max-age">, so
|
|
that there is not an unreasonably short time between forced
|
|
autovacuums. For more information see <xref
|
|
linkend="vacuum-for-wraparound">.
|
|
</para>
|
|
</listitem>
|
|
</varlistentry>
|
|
|
|
<varlistentry id="guc-bytea-output" xreflabel="bytea_output">
|
|
<term><varname>bytea_output</varname> (<type>enum</type>)</term>
|
|
<indexterm>
|
|
<primary><varname>bytea_output</> configuration parameter</primary>
|
|
</indexterm>
|
|
<listitem>
|
|
<para>
|
|
Sets the output format for values of type <type>bytea</type>.
|
|
Valid values are <literal>hex</literal> (the default)
|
|
and <literal>escape</literal> (the traditional PostgreSQL
|
|
format). See <xref linkend="datatype-binary"> for more
|
|
information. The <type>bytea</type> type always
|
|
accepts both formats on input, regardless of this setting.
|
|
</para>
|
|
</listitem>
|
|
</varlistentry>
|
|
|
|
<varlistentry id="guc-xmlbinary" xreflabel="xmlbinary">
|
|
<term><varname>xmlbinary</varname> (<type>enum</type>)</term>
|
|
<indexterm>
|
|
<primary><varname>xmlbinary</> configuration parameter</primary>
|
|
</indexterm>
|
|
<listitem>
|
|
<para>
|
|
Sets how binary values are to be encoded in XML. This applies
|
|
for example when <type>bytea</type> values are converted to
|
|
XML by the functions <function>xmlelement</function> or
|
|
<function>xmlforest</function>. Possible values are
|
|
<literal>base64</literal> and <literal>hex</literal>, which
|
|
are both defined in the XML Schema standard. The default is
|
|
<literal>base64</literal>. For further information about
|
|
XML-related functions, see <xref linkend="functions-xml">.
|
|
</para>
|
|
|
|
<para>
|
|
The actual choice here is mostly a matter of taste,
|
|
constrained only by possible restrictions in client
|
|
applications. Both methods support all possible values,
|
|
although the hex encoding will be somewhat larger than the
|
|
base64 encoding.
|
|
</para>
|
|
</listitem>
|
|
</varlistentry>
|
|
|
|
<varlistentry id="guc-xmloption" xreflabel="xmloption">
|
|
<term><varname>xmloption</varname> (<type>enum</type>)</term>
|
|
<indexterm>
|
|
<primary><varname>xmloption</> configuration parameter</primary>
|
|
</indexterm>
|
|
<indexterm>
|
|
<primary><varname>SET XML OPTION</></primary>
|
|
</indexterm>
|
|
<indexterm>
|
|
<primary>XML option</primary>
|
|
</indexterm>
|
|
<listitem>
|
|
<para>
|
|
Sets whether <literal>DOCUMENT</literal> or
|
|
<literal>CONTENT</literal> is implicit when converting between
|
|
XML and character string values. See <xref
|
|
linkend="datatype-xml"> for a description of this. Valid
|
|
values are <literal>DOCUMENT</literal> and
|
|
<literal>CONTENT</literal>. The default is
|
|
<literal>CONTENT</literal>.
|
|
</para>
|
|
|
|
<para>
|
|
According to the SQL standard, the command to set this option is
|
|
<synopsis>
|
|
SET XML OPTION { DOCUMENT | CONTENT };
|
|
</synopsis>
|
|
This syntax is also available in PostgreSQL.
|
|
</para>
|
|
</listitem>
|
|
</varlistentry>
|
|
|
|
</variablelist>
|
|
</sect2>
|
|
<sect2 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
|
|
built-in default is <literal>ISO, MDY</>, but
|
|
<application>initdb</application> will initialize the
|
|
configuration file with a setting that corresponds to the
|
|
behavior of the chosen <varname>lc_time</varname> locale.
|
|
</para>
|
|
</listitem>
|
|
</varlistentry>
|
|
|
|
<varlistentry id="guc-intervalstyle" xreflabel="IntervalStyle">
|
|
<term><varname>IntervalStyle</varname> (<type>enum</type>)</term>
|
|
<indexterm>
|
|
<primary><varname>IntervalStyle</> configuration parameter</primary>
|
|
</indexterm>
|
|
<listitem>
|
|
<para>
|
|
Sets the display format for interval values.
|
|
The value <literal>sql_standard</> will produce
|
|
output matching <acronym>SQL</acronym> standard interval literals.
|
|
The value <literal>postgres</> (which is the default) will produce
|
|
output matching <productname>PostgreSQL</> releases prior to 8.4
|
|
when the <xref linkend="guc-datestyle">
|
|
parameter was set to <literal>ISO</>.
|
|
The value <literal>postgres_verbose</> will produce output
|
|
matching <productname>PostgreSQL</> releases prior to 8.4
|
|
when the <varname>DateStyle</>
|
|
parameter was set to non-<literal>ISO</> output.
|
|
The value <literal>iso_8601</> will produce output matching the time
|
|
interval <quote>format with designators</> defined in section
|
|
4.4.3.2 of ISO 8601.
|
|
</para>
|
|
<para>
|
|
The <varname>IntervalStyle</> parameter also affects the
|
|
interpretation of ambiguous interval input. See
|
|
<xref linkend="datatype-interval-input"> for more information.
|
|
</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 built-in default is <literal>GMT</>, but that is typically
|
|
overridden in <filename>postgresql.conf</>; <application>initdb</>
|
|
will install a setting there corresponding to its system environment.
|
|
See <xref linkend="datatype-timezones"> for more information.
|
|
</para>
|
|
</listitem>
|
|
</varlistentry>
|
|
|
|
<varlistentry id="guc-timezone-abbreviations" xreflabel="timezone_abbreviations">
|
|
<term><varname>timezone_abbreviations</varname> (<type>string</type>)</term>
|
|
<indexterm>
|
|
<primary><varname>timezone_abbreviations</> configuration parameter</primary>
|
|
</indexterm>
|
|
<indexterm><primary>time zone names</></>
|
|
<listitem>
|
|
<para>
|
|
Sets the collection of time zone abbreviations that will be accepted
|
|
by the server for datetime input. The default is <literal>'Default'</>,
|
|
which is a collection that works in most of the world; there are
|
|
also <literal>'Australia'</literal> and <literal>'India'</literal>, and other collections can be defined
|
|
for a particular installation. See <xref
|
|
linkend="datetime-appendix"> for more information.
|
|
</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 3, 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.
|
|
The character sets supported by the <productname>PostgreSQL</productname>
|
|
server are described in <xref linkend="multibyte-charset-supported">.
|
|
</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>
|
|
|
|
<para>
|
|
Only superusers can change this setting, because it affects the
|
|
messages sent to the server log as well as to the client, and
|
|
an improper value might obscure the readability of the server
|
|
logs.
|
|
</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 dates and times, 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-default-text-search-config" xreflabel="default_text_search_config">
|
|
<term><varname>default_text_search_config</varname> (<type>string</type>)</term>
|
|
<indexterm>
|
|
<primary><varname>default_text_search_config</> configuration parameter</primary>
|
|
</indexterm>
|
|
<listitem>
|
|
<para>
|
|
Selects the text search configuration that is used by those variants
|
|
of the text search functions that do not have an explicit argument
|
|
specifying the configuration.
|
|
See <xref linkend="textsearch"> for further information.
|
|
The built-in default is <literal>pg_catalog.simple</>, but
|
|
<application>initdb</application> will initialize the
|
|
configuration file with a setting that corresponds to the
|
|
chosen <varname>lc_ctype</varname> locale, if a configuration
|
|
matching that locale can be identified.
|
|
</para>
|
|
</listitem>
|
|
</varlistentry>
|
|
|
|
</variablelist>
|
|
|
|
</sect2>
|
|
<sect2 id="runtime-config-client-other">
|
|
<title>Other Defaults</title>
|
|
|
|
<variablelist>
|
|
|
|
<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> must 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>
|
|
|
|
<varlistentry id="guc-gin-fuzzy-search-limit" xreflabel="gin_fuzzy_search_limit">
|
|
<term><varname>gin_fuzzy_search_limit</varname> (<type>integer</type>)</term>
|
|
<indexterm>
|
|
<primary><varname>gin_fuzzy_search_limit</> configuration parameter</primary>
|
|
</indexterm>
|
|
<listitem>
|
|
<para>
|
|
Soft upper limit of the size of the set returned by GIN index scans. For more
|
|
information see <xref linkend="gin-tips">.
|
|
</para>
|
|
</listitem>
|
|
</varlistentry>
|
|
|
|
<varlistentry id="guc-local-preload-libraries" xreflabel="local_preload_libraries">
|
|
<term><varname>local_preload_libraries</varname> (<type>string</type>)</term>
|
|
<indexterm>
|
|
<primary><varname>local_preload_libraries</> configuration parameter</primary>
|
|
</indexterm>
|
|
<indexterm>
|
|
<primary><filename>$libdir/plugins</></primary>
|
|
</indexterm>
|
|
<listitem>
|
|
<para>
|
|
This variable specifies one or more shared libraries that are
|
|
to be preloaded at connection start. If more than one library
|
|
is to be loaded, separate their names with commas. All library
|
|
names are converted to lower case unless double-quoted.
|
|
This parameter cannot be changed after the start of a particular
|
|
session.
|
|
</para>
|
|
|
|
<para>
|
|
Because this is not a superuser-only option, the libraries
|
|
that can be loaded are restricted to those appearing in the
|
|
<filename>plugins</> subdirectory of the installation's
|
|
standard library directory. (It is the database administrator's
|
|
responsibility to ensure that only <quote>safe</> libraries
|
|
are installed there.) Entries in <varname>local_preload_libraries</>
|
|
can specify this directory explicitly, for example
|
|
<literal>$libdir/plugins/mylib</literal>, or just specify
|
|
the library name — <literal>mylib</literal> would have
|
|
the same effect as <literal>$libdir/plugins/mylib</literal>.
|
|
</para>
|
|
|
|
<para>
|
|
Unlike <xref linkend="guc-shared-preload-libraries">, there is no
|
|
performance advantage to loading a library at session
|
|
start rather than when it is first used. Rather, the intent of
|
|
this feature is to allow debugging or performance-measurement
|
|
libraries to be loaded into specific sessions without an explicit
|
|
<command>LOAD</> command being given. For example, debugging could
|
|
be enabled for all sessions under a given user name by setting
|
|
this parameter with <command>ALTER ROLE SET</>.
|
|
</para>
|
|
|
|
<para>
|
|
If a specified library is not found,
|
|
the connection attempt will fail.
|
|
</para>
|
|
|
|
<para>
|
|
Every PostgreSQL-supported library has a <quote>magic
|
|
block</> that is checked to guarantee compatibility.
|
|
For this reason, non-PostgreSQL libraries cannot be
|
|
loaded in this way.
|
|
</para>
|
|
</listitem>
|
|
</varlistentry>
|
|
|
|
</variablelist>
|
|
</sect2>
|
|
</sect1>
|
|
|
|
<sect1 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 expensive, 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 checking 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 one second (<literal>1s</>),
|
|
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. Only superusers can change
|
|
this setting.
|
|
</para>
|
|
|
|
<para>
|
|
When <xref linkend="guc-log-lock-waits"> is set,
|
|
this parameter also determines the length of time to wait before
|
|
a log message is issued about the lock wait. If you are trying
|
|
to investigate locking delays you might want to set a shorter than
|
|
normal <varname>deadlock_timeout</varname>.
|
|
</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 tracks locks on
|
|
<varname>max_locks_per_transaction</varname> * (<xref
|
|
linkend="guc-max-connections"> + <xref
|
|
linkend="guc-max-prepared-transactions">) objects (e.g., tables);
|
|
hence, no more than this many distinct objects can be locked at
|
|
any one time. This parameter controls the average number of object
|
|
locks allocated for each transaction; individual transactions
|
|
can lock more objects as long as the locks of all transactions
|
|
fit in the lock table. This is <emphasis>not</> the number of
|
|
rows that can be locked; that value is unlimited. 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 parameter can only be set at
|
|
server start.
|
|
</para>
|
|
|
|
<para>
|
|
Increasing this parameter might 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>
|
|
|
|
<para>
|
|
When running a standby server, you must set this parameter to the
|
|
same or higher value than on the master server. Otherwise, queries
|
|
will not be allowed in the standby server.
|
|
</para>
|
|
</listitem>
|
|
</varlistentry>
|
|
|
|
<varlistentry id="guc-max-pred-locks-per-transaction" xreflabel="max_pred_locks_per_transaction">
|
|
<term><varname>max_pred_locks_per_transaction</varname> (<type>integer</type>)</term>
|
|
<indexterm>
|
|
<primary><varname>max_pred_locks_per_transaction</> configuration parameter</primary>
|
|
</indexterm>
|
|
<listitem>
|
|
<para>
|
|
The shared predicate lock table tracks locks on
|
|
<varname>max_pred_locks_per_transaction</varname> * (<xref
|
|
linkend="guc-max-connections"> + <xref
|
|
linkend="guc-max-prepared-transactions">) objects (e.g., tables);
|
|
hence, no more than this many distinct objects can be locked at
|
|
any one time. This parameter controls the average number of object
|
|
locks allocated for each transaction; individual transactions
|
|
can lock more objects as long as the locks of all transactions
|
|
fit in the lock table. This is <emphasis>not</> the number of
|
|
rows that can be locked; that value is unlimited. The default,
|
|
64, has generally been sufficient in testing, but you might need to
|
|
raise this value if you have clients that touch many different
|
|
tables in a single serializable transaction. This parameter can
|
|
only be set at server start.
|
|
</para>
|
|
|
|
<para>
|
|
Increasing this parameter might 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>
|
|
|
|
</variablelist>
|
|
</sect1>
|
|
|
|
<sect1 id="runtime-config-compatible">
|
|
<title>Version and Platform Compatibility</title>
|
|
|
|
<sect2 id="runtime-config-compatible-version">
|
|
<title>Previous PostgreSQL Versions</title>
|
|
|
|
<variablelist>
|
|
|
|
<varlistentry id="guc-array-nulls" xreflabel="array_nulls">
|
|
<term><varname>array_nulls</varname> (<type>boolean</type>)</term>
|
|
<indexterm>
|
|
<primary><varname>array_nulls</> configuration parameter</primary>
|
|
</indexterm>
|
|
<listitem>
|
|
<para>
|
|
This controls whether the array input parser recognizes
|
|
unquoted <literal>NULL</> as specifying a null array element.
|
|
By default, this is <literal>on</>, allowing array values containing
|
|
null values to be entered. However, <productname>PostgreSQL</> versions
|
|
before 8.2 did not support null values in arrays, and therefore would
|
|
treat <literal>NULL</> as specifying a normal array element with
|
|
the string value <quote>NULL</>. For backward compatibility with
|
|
applications that require the old behavior, this variable can be
|
|
turned <literal>off</>.
|
|
</para>
|
|
|
|
<para>
|
|
Note that it is possible to create array values containing null values
|
|
even when this variable is <literal>off</>.
|
|
</para>
|
|
</listitem>
|
|
</varlistentry>
|
|
|
|
<varlistentry id="guc-backslash-quote" xreflabel="backslash_quote">
|
|
<term><varname>backslash_quote</varname> (<type>enum</type>)</term>
|
|
<indexterm><primary>strings</><secondary>backslash quotes</></>
|
|
<indexterm>
|
|
<primary><varname>backslash_quote</> configuration parameter</primary>
|
|
</indexterm>
|
|
<listitem>
|
|
<para>
|
|
This controls whether a quote mark can be represented by
|
|
<literal>\'</> in a string literal. The preferred, SQL-standard way
|
|
to represent a quote mark is by doubling it (<literal>''</>) but
|
|
<productname>PostgreSQL</> has historically also accepted
|
|
<literal>\'</>. However, use of <literal>\'</> creates security risks
|
|
because in some client character set encodings, there are multibyte
|
|
characters in which the last byte is numerically equivalent to ASCII
|
|
<literal>\</>. If client-side code does escaping incorrectly then a
|
|
SQL-injection attack is possible. This risk can be prevented by
|
|
making the server reject queries in which a quote mark appears to be
|
|
escaped by a backslash.
|
|
The allowed values of <varname>backslash_quote</> are
|
|
<literal>on</> (allow <literal>\'</> always),
|
|
<literal>off</> (reject always), and
|
|
<literal>safe_encoding</> (allow only if client encoding does not
|
|
allow ASCII <literal>\</> within a multibyte character).
|
|
<literal>safe_encoding</> is the default setting.
|
|
</para>
|
|
|
|
<para>
|
|
Note that in a standard-conforming string literal, <literal>\</> just
|
|
means <literal>\</> anyway. This parameter only affects the handling of
|
|
non-standard-conforming literals, including
|
|
escape string syntax (<literal>E'...'</>).
|
|
</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>. The parameter is <literal>off</>
|
|
by default; in <productname>PostgreSQL</> 8.0 and earlier, it
|
|
was on by default.
|
|
</para>
|
|
|
|
<para>
|
|
The use of OIDs in user tables is considered deprecated, so
|
|
most installations should leave this variable disabled.
|
|
Applications that require OIDs for a particular table should
|
|
specify <literal>WITH OIDS</literal> when creating the
|
|
table. This variable can be enabled for compatibility with old
|
|
applications that do not follow this behavior.
|
|
</para>
|
|
</listitem>
|
|
</varlistentry>
|
|
|
|
<varlistentry id="guc-escape-string-warning" xreflabel="escape_string_warning">
|
|
<term><varname>escape_string_warning</varname> (<type>boolean</type>)</term>
|
|
<indexterm><primary>strings</><secondary>escape warning</></>
|
|
<indexterm>
|
|
<primary><varname>escape_string_warning</> configuration parameter</primary>
|
|
</indexterm>
|
|
<listitem>
|
|
<para>
|
|
When on, a warning is issued if a backslash (<literal>\</>)
|
|
appears in an ordinary string literal (<literal>'...'</>
|
|
syntax) and <varname>standard_conforming_strings</varname> is off.
|
|
The default is <literal>on</>.
|
|
</para>
|
|
<para>
|
|
Applications that wish to use backslash as escape should be
|
|
modified to use escape string syntax (<literal>E'...'</>),
|
|
because the default behavior of ordinary strings is now to treat
|
|
backslash as an ordinary character, per SQL standard. This variable
|
|
can be enabled to help locate code that needs to be changed.
|
|
</para>
|
|
</listitem>
|
|
</varlistentry>
|
|
|
|
<varlistentry id="guc-lo-compat-privileges" xreflabel="lo_compat_privileges">
|
|
<term><varname>lo_compat_privileges</varname> (<type>boolean</type>)</term>
|
|
<indexterm>
|
|
<primary><varname>lo_compat_privileges</> configuration parameter</primary>
|
|
</indexterm>
|
|
<listitem>
|
|
<para>
|
|
In <productname>PostgreSQL</> releases prior to 9.0, large objects
|
|
did not have access privileges and were, in effect, readable and
|
|
writable by all users. Setting this variable to <literal>on</>
|
|
disables the new privilege checks, for compatibility with prior
|
|
releases. The default is <literal>off</>.
|
|
</para>
|
|
<para>
|
|
Setting this variable does not disable all security checks related to
|
|
large objects — only those for which the default behavior has
|
|
changed in <productname>PostgreSQL</> 9.0.
|
|
For example, <literal>lo_import()</literal> and
|
|
<literal>lo_export()</literal> need superuser privileges independent
|
|
of this setting.
|
|
</para>
|
|
</listitem>
|
|
</varlistentry>
|
|
|
|
<varlistentry id="guc-quote-all-identifiers" xreflabel="quote-all-identifiers">
|
|
<term><varname>quote_all_identifiers</varname> (<type>boolean</type>)</term>
|
|
<indexterm>
|
|
<primary><varname>quote_all_identifiers</> configuration parameter</primary>
|
|
</indexterm>
|
|
<listitem>
|
|
<para>
|
|
When the database generates SQL, force all identifiers to be quoted,
|
|
even if they are not (currently) keywords. This will affect the
|
|
output of <command>EXPLAIN</> as well as the results of functions
|
|
like <function>pg_get_viewdef</>. See also the
|
|
<option>--quote-all-identifiers</option> option of
|
|
<xref linkend="app-pgdump"> and <xref linkend="app-pg-dumpall">.
|
|
</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. If turned <literal>off</>,
|
|
subtables are not accessed by various commands by default; basically
|
|
an implied <literal>ONLY</literal> key word. This was added for
|
|
compatibility with releases prior to 7.1. See
|
|
<xref linkend="ddl-inherit"> for more information.
|
|
</para>
|
|
</listitem>
|
|
</varlistentry>
|
|
|
|
<varlistentry id="guc-standard-conforming-strings" xreflabel="standard_conforming_strings">
|
|
<term><varname>standard_conforming_strings</varname> (<type>boolean</type>)</term>
|
|
<indexterm><primary>strings</><secondary>standard conforming</></>
|
|
<indexterm>
|
|
<primary><varname>standard_conforming_strings</> configuration parameter</primary>
|
|
</indexterm>
|
|
<listitem>
|
|
<para>
|
|
This controls whether ordinary string literals
|
|
(<literal>'...'</>) treat backslashes literally, as specified in
|
|
the SQL standard.
|
|
Beginning in <productname>PostgreSQL</productname> 9.1, the default is
|
|
<literal>on</> (prior releases defaulted to <literal>off</>).
|
|
Applications can check this
|
|
parameter to determine how string literals will be processed.
|
|
The presence of this parameter can also be taken as an indication
|
|
that the escape string syntax (<literal>E'...'</>) is supported.
|
|
Escape string syntax (<xref linkend="sql-syntax-strings-escape">)
|
|
should be used if an application desires
|
|
backslashes to be treated as escape characters.
|
|
</para>
|
|
</listitem>
|
|
</varlistentry>
|
|
|
|
<varlistentry id="guc-synchronize-seqscans" xreflabel="synchronize_seqscans">
|
|
<term><varname>synchronize_seqscans</varname> (<type>boolean</type>)</term>
|
|
<indexterm>
|
|
<primary><varname>synchronize_seqscans</> configuration parameter</primary>
|
|
</indexterm>
|
|
<listitem>
|
|
<para>
|
|
This allows sequential scans of large tables to synchronize with each
|
|
other, so that concurrent scans read the same block at about the
|
|
same time and hence share the I/O workload. When this is enabled,
|
|
a scan might start in the middle of the table and then <quote>wrap
|
|
around</> the end to cover all rows, so as to synchronize with the
|
|
activity of scans already in progress. This can result in
|
|
unpredictable changes in the row ordering returned by queries that
|
|
have no <literal>ORDER BY</> clause. Setting this parameter to
|
|
<literal>off</> ensures the pre-8.3 behavior in which a sequential
|
|
scan always starts from the beginning of the table. The default
|
|
is <literal>on</>.
|
|
</para>
|
|
</listitem>
|
|
</varlistentry>
|
|
|
|
</variablelist>
|
|
</sect2>
|
|
|
|
<sect2 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 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 parameter defaults to
|
|
<literal>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 SQL standard 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 off 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>
|
|
</sect2>
|
|
</sect1>
|
|
|
|
<sect1 id="runtime-config-error-handling">
|
|
<title>Error Handling</title>
|
|
|
|
<variablelist>
|
|
|
|
<varlistentry id="guc-exit-on-error" xreflabel="exit_on_error">
|
|
<term><varname>exit_on_error</varname> (<type>boolean</type>)</term>
|
|
<indexterm>
|
|
<primary><varname>exit_on_error</> configuration parameter</primary>
|
|
</indexterm>
|
|
<listitem>
|
|
<para>
|
|
If true, any error will terminate the current session. By default,
|
|
this is set to false, so that only FATAL errors will terminate the
|
|
session.
|
|
</para>
|
|
</listitem>
|
|
</varlistentry>
|
|
|
|
<varlistentry id="guc-restart-after-crash" xreflabel="restart_after_crash">
|
|
<term><varname>restart_after_crash</varname> (<type>boolean</type>)</term>
|
|
<indexterm>
|
|
<primary><varname>restart_after_crash</> configuration parameter</primary>
|
|
</indexterm>
|
|
<listitem>
|
|
<para>
|
|
When set to true, which is the default, <productname>PostgreSQL</>
|
|
will automatically reinitialize after a backend crash. Leaving this
|
|
value set to true is normally the best way to maximize the availability
|
|
of the database. However, in some circumstances, such as when
|
|
<productname>PostgreSQL</> is being invoked by clusterware, it may be
|
|
useful to disable the restart so that the clusterware can gain
|
|
control and take any actions it deems appropriate.
|
|
</para>
|
|
</listitem>
|
|
</varlistentry>
|
|
|
|
</variablelist>
|
|
|
|
</sect1>
|
|
|
|
<sect1 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 might 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>
|
|
Reports 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>
|
|
Reports whether <productname>PostgreSQL</> was built with
|
|
support for 64-bit-integer dates and times. This can be
|
|
disabled by configuring with <literal>--disable-integer-datetimes</>
|
|
when building <productname>PostgreSQL</>. The default value is
|
|
<literal>on</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>
|
|
Reports the locale in which sorting of textual data is done.
|
|
See <xref linkend="locale"> for more information.
|
|
This value is determined when a database is created.
|
|
</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>
|
|
Reports the locale that determines character classifications.
|
|
See <xref linkend="locale"> for more information.
|
|
This value is determined when a database is created.
|
|
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>
|
|
Reports 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 100 arguments.
|
|
</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>
|
|
Reports 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 bytes, which
|
|
can be less than 63 characters when using multibyte encodings.
|
|
</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>
|
|
Reports 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 keys.
|
|
</para>
|
|
</listitem>
|
|
</varlistentry>
|
|
|
|
<varlistentry id="guc-segment-size" xreflabel="segment_size">
|
|
<term><varname>segment_size</varname> (<type>integer</type>)</term>
|
|
<indexterm>
|
|
<primary><varname>segment_size</> configuration parameter</primary>
|
|
</indexterm>
|
|
<listitem>
|
|
<para>
|
|
Reports the number of blocks (pages) that can be stored within a file
|
|
segment. It is determined by the value of <literal>RELSEG_SIZE</>
|
|
when building the server. The maximum size of a segment file in bytes
|
|
is equal to <varname>segment_size</> multiplied by
|
|
<varname>block_size</>; by default this is 1GB.
|
|
</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>
|
|
Reports 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>
|
|
Reports the version number of the server. It is determined by the
|
|
value of <literal>PG_VERSION</> when building the server.
|
|
</para>
|
|
</listitem>
|
|
</varlistentry>
|
|
|
|
<varlistentry id="guc-server-version-num" xreflabel="server_version_num">
|
|
<term><varname>server_version_num</varname> (<type>integer</type>)</term>
|
|
<indexterm>
|
|
<primary><varname>server_version_num</> configuration parameter</primary>
|
|
</indexterm>
|
|
<listitem>
|
|
<para>
|
|
Reports the version number of the server as an integer. It is determined
|
|
by the value of <literal>PG_VERSION_NUM</> when building the server.
|
|
</para>
|
|
</listitem>
|
|
</varlistentry>
|
|
|
|
<varlistentry id="guc-wal-block-size" xreflabel="wal_block_size">
|
|
<term><varname>wal_block_size</varname> (<type>integer</type>)</term>
|
|
<indexterm>
|
|
<primary><varname>wal_block_size</> configuration parameter</primary>
|
|
</indexterm>
|
|
<listitem>
|
|
<para>
|
|
Reports the size of a WAL disk block. It is determined by the value
|
|
of <literal>XLOG_BLCKSZ</> when building the server. The default value
|
|
is 8192 bytes.
|
|
</para>
|
|
</listitem>
|
|
</varlistentry>
|
|
|
|
<varlistentry id="guc-wal-segment-size" xreflabel="wal_segment_size">
|
|
<term><varname>wal_segment_size</varname> (<type>integer</type>)</term>
|
|
<indexterm>
|
|
<primary><varname>wal_segment_size</> configuration parameter</primary>
|
|
</indexterm>
|
|
<listitem>
|
|
<para>
|
|
Reports the number of blocks (pages) in a WAL segment file.
|
|
The total size of a WAL segment file in bytes is equal to
|
|
<varname>wal_segment_size</> multiplied by <varname>wal_block_size</>;
|
|
by default this is 16MB. See <xref linkend="wal-configuration"> for
|
|
more information.
|
|
</para>
|
|
</listitem>
|
|
</varlistentry>
|
|
|
|
</variablelist>
|
|
</sect1>
|
|
|
|
<sect1 id="runtime-config-custom">
|
|
<title>Customized Options</title>
|
|
|
|
<para>
|
|
This feature was designed to allow parameters 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 parameter can only be set in the <filename>postgresql.conf</>
|
|
file or on the server command line.
|
|
</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
|
|
unrecognized placeholders of its class that remain.
|
|
</para>
|
|
|
|
<para>
|
|
Here is an example of what <filename>postgresql.conf</> might contain
|
|
when using custom variables:
|
|
|
|
<programlisting>
|
|
custom_variable_classes = 'plpgsql,plperl'
|
|
plpgsql.variable_conflict = use_variable
|
|
plperl.use_strict = true
|
|
plruby.use_strict = true # generates error: unknown class name
|
|
</programlisting>
|
|
</para>
|
|
</sect1>
|
|
|
|
<sect1 id="runtime-config-developer">
|
|
<title>Developer Options</title>
|
|
|
|
<para>
|
|
The following parameters are intended for work on the
|
|
<productname>PostgreSQL</productname> source code, and in some cases
|
|
to assist with recovery of severely damaged databases. There
|
|
should be no reason to use them on a production database.
|
|
As such, they have been excluded from the sample
|
|
<filename>postgresql.conf</> file. Note that many of these
|
|
parameters require special source compilation flags to work at all.
|
|
</para>
|
|
|
|
<variablelist>
|
|
<varlistentry id="guc-allow-system-table-mods" xreflabel="allow_system_table_mods">
|
|
<term><varname>allow_system_table_mods</varname> (<type>boolean</type>)</term>
|
|
<indexterm>
|
|
<primary><varname>allow_system_table_mods</varname> configuration parameter</primary>
|
|
</indexterm>
|
|
<listitem>
|
|
<para>
|
|
Allows modification of the structure of system tables.
|
|
This is used by <command>initdb</command>.
|
|
This parameter can only be set at server start.
|
|
</para>
|
|
</listitem>
|
|
</varlistentry>
|
|
|
|
<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 parameter, 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 <literal>on</>
|
|
if <productname>PostgreSQL</productname> has been built with
|
|
assertions enabled.
|
|
</para>
|
|
</listitem>
|
|
</varlistentry>
|
|
|
|
<varlistentry id="guc-ignore-system-indexes" xreflabel="ignore_system_indexes">
|
|
<term><varname>ignore_system_indexes</varname> (<type>boolean</type>)</term>
|
|
<indexterm>
|
|
<primary><varname>ignore_system_indexes</varname> configuration parameter</primary>
|
|
</indexterm>
|
|
<listitem>
|
|
<para>
|
|
Ignore system indexes when reading system tables (but still
|
|
update the indexes when modifying the tables). This is useful
|
|
when recovering from damaged system indexes.
|
|
This parameter cannot be changed after session start.
|
|
</para>
|
|
</listitem>
|
|
</varlistentry>
|
|
|
|
<varlistentry id="guc-post-auth-delay" xreflabel="post_auth_delay">
|
|
<term><varname>post_auth_delay</varname> (<type>integer</type>)</term>
|
|
<indexterm>
|
|
<primary><varname>post_auth_delay</> configuration parameter</primary>
|
|
</indexterm>
|
|
<listitem>
|
|
<para>
|
|
If nonzero, a delay of this many seconds occurs when a new
|
|
server process is started, after it conducts the
|
|
authentication procedure. This is intended to give developers an
|
|
opportunity to attach to the server process with a debugger.
|
|
This parameter cannot be changed after session start.
|
|
</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 procedure. This is intended to give developers an
|
|
opportunity to attach to the server process with a debugger to
|
|
trace down misbehavior in authentication.
|
|
This parameter can only be set in the <filename>postgresql.conf</>
|
|
file or on the server command line.
|
|
</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 logs, respectively.
|
|
</para>
|
|
</listitem>
|
|
</varlistentry>
|
|
|
|
<varlistentry id="guc-trace-recovery-messages" xreflabel="trace_recovery_messages">
|
|
<term><varname>trace_recovery_messages</varname> (<type>enum</type>)</term>
|
|
<indexterm>
|
|
<primary><varname>trace_recovery_messages</> configuration parameter</primary>
|
|
</indexterm>
|
|
<listitem>
|
|
<para>
|
|
Enables logging of recovery-related debugging output that otherwise
|
|
would not be logged. This parameter allows the user to override the
|
|
normal setting of <xref linkend="guc-log-min-messages">, but only for
|
|
specific messages. This is intended for use in debugging Hot Standby.
|
|
Valid values are <literal>DEBUG5</>, <literal>DEBUG4</>,
|
|
<literal>DEBUG3</>, <literal>DEBUG2</>, <literal>DEBUG1</>, and
|
|
<literal>LOG</>. The default, <literal>LOG</>, does not affect
|
|
logging decisions at all. The other values cause recovery-related
|
|
debug messages of that priority or higher to be logged as though they
|
|
had <literal>LOG</> priority; for common settings of
|
|
<varname>log_min_messages</> this results in unconditionally sending
|
|
them to the server log.
|
|
This parameter can only be set in the <filename>postgresql.conf</>
|
|
file or on the server command line.
|
|
</para>
|
|
</listitem>
|
|
</varlistentry>
|
|
|
|
<varlistentry id="guc-trace-sort" xreflabel="trace_sort">
|
|
<term><varname>trace_sort</varname> (<type>boolean</type>)</term>
|
|
<indexterm>
|
|
<primary><varname>trace_sort</> configuration parameter</primary>
|
|
</indexterm>
|
|
<listitem>
|
|
<para>
|
|
If on, emit information about resource usage during sort operations.
|
|
This parameter is only available if the <symbol>TRACE_SORT</symbol> macro
|
|
was defined when <productname>PostgreSQL</productname> was compiled.
|
|
(However, <symbol>TRACE_SORT</symbol> is currently defined by default.)
|
|
</para>
|
|
</listitem>
|
|
</varlistentry>
|
|
|
|
<varlistentry>
|
|
<term><varname>trace_locks</varname> (<type>boolean</type>)</term>
|
|
<indexterm>
|
|
<primary><varname>trace_locks</> configuration parameter</primary>
|
|
</indexterm>
|
|
<listitem>
|
|
<para>
|
|
If on, emit information about lock usage. Information dumped
|
|
includes the type of lock operation, the type of lock and the unique
|
|
identifier of the object being locked or unlocked. Also included
|
|
are bit masks for the lock types already granted on this object as
|
|
well as for the lock types awaited on this object. For each lock
|
|
type a count of the number of granted locks and waiting locks is
|
|
also dumped as well as the totals. An example of the log file output
|
|
is shown here:
|
|
<screen>
|
|
LOG: LockAcquire: new: lock(0xb7acd844) id(24688,24696,0,0,0,1)
|
|
grantMask(0) req(0,0,0,0,0,0,0)=0 grant(0,0,0,0,0,0,0)=0
|
|
wait(0) type(AccessShareLock)
|
|
LOG: GrantLock: lock(0xb7acd844) id(24688,24696,0,0,0,1)
|
|
grantMask(2) req(1,0,0,0,0,0,0)=1 grant(1,0,0,0,0,0,0)=1
|
|
wait(0) type(AccessShareLock)
|
|
LOG: UnGrantLock: updated: lock(0xb7acd844) id(24688,24696,0,0,0,1)
|
|
grantMask(0) req(0,0,0,0,0,0,0)=0 grant(0,0,0,0,0,0,0)=0
|
|
wait(0) type(AccessShareLock)
|
|
LOG: CleanUpLock: deleting: lock(0xb7acd844) id(24688,24696,0,0,0,1)
|
|
grantMask(0) req(0,0,0,0,0,0,0)=0 grant(0,0,0,0,0,0,0)=0
|
|
wait(0) type(INVALID)
|
|
</screen>
|
|
Details of the structure being dumped may be found in
|
|
<filename>src/include/storage/lock.h</filename>.
|
|
</para>
|
|
<para>
|
|
This parameter is only available if the <symbol>LOCK_DEBUG</symbol>
|
|
macro was defined when <productname>PostgreSQL</productname> was
|
|
compiled.
|
|
</para>
|
|
</listitem>
|
|
</varlistentry>
|
|
|
|
<varlistentry>
|
|
<term><varname>trace_lwlocks</varname> (<type>boolean</type>)</term>
|
|
<indexterm>
|
|
<primary><varname>trace_lwlocks</> configuration parameter</primary>
|
|
</indexterm>
|
|
<listitem>
|
|
<para>
|
|
If on, emit information about lightweight lock usage. Lightweight
|
|
locks are intended primarily to provide mutual exclusion of access
|
|
to shared-memory data structures.
|
|
</para>
|
|
<para>
|
|
This parameter is only available if the <symbol>LOCK_DEBUG</symbol>
|
|
macro was defined when <productname>PostgreSQL</productname> was
|
|
compiled.
|
|
</para>
|
|
</listitem>
|
|
</varlistentry>
|
|
|
|
<varlistentry>
|
|
<term><varname>trace_userlocks</varname> (<type>boolean</type>)</term>
|
|
<indexterm>
|
|
<primary><varname>trace_userlocks</> configuration parameter</primary>
|
|
</indexterm>
|
|
<listitem>
|
|
<para>
|
|
If on, emit information about user lock usage. Output is the same
|
|
as for <symbol>trace_locks</symbol>, only for user locks.
|
|
</para>
|
|
<para>
|
|
User locks were removed as of PostgreSQL version 8.2. This option
|
|
currently has no effect.
|
|
</para>
|
|
<para>
|
|
This parameter is only available if the <symbol>LOCK_DEBUG</symbol>
|
|
macro was defined when <productname>PostgreSQL</productname> was
|
|
compiled.
|
|
</para>
|
|
</listitem>
|
|
</varlistentry>
|
|
|
|
<varlistentry>
|
|
<term><varname>trace_lock_oidmin</varname> (<type>integer</type>)</term>
|
|
<indexterm>
|
|
<primary><varname>trace_lock_oidmin</> configuration parameter</primary>
|
|
</indexterm>
|
|
<listitem>
|
|
<para>
|
|
If set, do not trace locks for tables below this OID. (use to avoid
|
|
output on system tables)
|
|
</para>
|
|
<para>
|
|
This parameter is only available if the <symbol>LOCK_DEBUG</symbol>
|
|
macro was defined when <productname>PostgreSQL</productname> was
|
|
compiled.
|
|
</para>
|
|
</listitem>
|
|
</varlistentry>
|
|
|
|
<varlistentry>
|
|
<term><varname>trace_lock_table</varname> (<type>integer</type>)</term>
|
|
<indexterm>
|
|
<primary><varname>trace_lock_table</> configuration parameter</primary>
|
|
</indexterm>
|
|
<listitem>
|
|
<para>
|
|
Unconditionally trace locks on this table (OID).
|
|
</para>
|
|
<para>
|
|
This parameter is only available if the <symbol>LOCK_DEBUG</symbol>
|
|
macro was defined when <productname>PostgreSQL</productname> was
|
|
compiled.
|
|
</para>
|
|
</listitem>
|
|
</varlistentry>
|
|
|
|
<varlistentry>
|
|
<term><varname>debug_deadlocks</varname> (<type>boolean</type>)</term>
|
|
<indexterm>
|
|
<primary><varname>debug_deadlocks</> configuration parameter</primary>
|
|
</indexterm>
|
|
<listitem>
|
|
<para>
|
|
If set, dumps information about all current locks when a
|
|
deadlock timeout occurs.
|
|
</para>
|
|
<para>
|
|
This parameter is only available if the <symbol>LOCK_DEBUG</symbol>
|
|
macro was defined when <productname>PostgreSQL</productname> was
|
|
compiled.
|
|
</para>
|
|
</listitem>
|
|
</varlistentry>
|
|
|
|
<varlistentry>
|
|
<term><varname>log_btree_build_stats</varname> (<type>boolean</type>)</term>
|
|
<indexterm>
|
|
<primary><varname>log_btree_build_stats</> configuration parameter</primary>
|
|
</indexterm>
|
|
<listitem>
|
|
<para>
|
|
If set, logs system resource usage statistics (memory and CPU) on
|
|
various B-tree operations.
|
|
</para>
|
|
<para>
|
|
This parameter is only available if the <symbol>BTREE_BUILD_STATS</symbol>
|
|
macro was defined when <productname>PostgreSQL</productname> was
|
|
compiled.
|
|
</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 on, emit WAL-related debugging output. This parameter 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
|
|
transaction. Setting <varname>zero_damaged_pages</> to on causes
|
|
the system to instead report a warning, zero out the damaged
|
|
page in memory, and continue processing. This behavior <emphasis>will destroy data</>,
|
|
namely all the rows on the damaged page. However, it does allow you to get
|
|
past the error and retrieve rows from any undamaged pages that might
|
|
be present in the table. It is useful for recovering data if
|
|
corruption has occurred due to a hardware or software error. You should
|
|
generally not set this on until you have given up hope of recovering
|
|
data from the damaged pages of a table. Zeroed-out pages are not
|
|
forced to disk so it is recommended to recreate the table or
|
|
the index before turning this parameter off again. The
|
|
default setting is <literal>off</>, and it can only be changed
|
|
by a superuser.
|
|
</para>
|
|
</listitem>
|
|
</varlistentry>
|
|
</variablelist>
|
|
</sect1>
|
|
<sect1 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">. Some of these
|
|
options exist for historical reasons, and their presence as a
|
|
single-letter option does not necessarily indicate an endorsement
|
|
to use the option heavily.
|
|
</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>-A <replaceable>x</replaceable></option></entry>
|
|
<entry><literal>debug_assertions = <replaceable>x</replaceable></></entry>
|
|
</row>
|
|
<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>-e</option></entry>
|
|
<entry><literal>datestyle = euro</></entry>
|
|
</row>
|
|
<row>
|
|
<entry>
|
|
<option>-fb</option>, <option>-fh</option>, <option>-fi</option>,
|
|
<option>-fm</option>, <option>-fn</option>,
|
|
<option>-fs</option>, <option>-ft</option>
|
|
</entry>
|
|
<entry>
|
|
<literal>enable_bitmapscan = off</>,
|
|
<literal>enable_hashjoin = off</>,
|
|
<literal>enable_indexscan = off</>,
|
|
<literal>enable_mergejoin = off</>,
|
|
<literal>enable_nestloop = off</>,
|
|
<literal>enable_seqscan = off</>,
|
|
<literal>enable_tidscan = off</>
|
|
</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>-O</option></entry>
|
|
<entry><literal>allow_system_table_mods = on</></entry>
|
|
</row>
|
|
<row>
|
|
<entry><option>-p <replaceable>x</replaceable></option></entry>
|
|
<entry><literal>port = <replaceable>x</replaceable></></entry>
|
|
</row>
|
|
<row>
|
|
<entry><option>-P</option></entry>
|
|
<entry><literal>ignore_system_indexes = on</></entry>
|
|
</row>
|
|
<row>
|
|
<entry><option>-s</option></entry>
|
|
<entry><literal>log_statement_stats = on</></entry>
|
|
</row>
|
|
<row>
|
|
<entry><option>-S <replaceable>x</replaceable></option></entry>
|
|
<entry><literal>work_mem = <replaceable>x</replaceable></></entry>
|
|
</row>
|
|
<row>
|
|
<entry><option>-tpa</option>, <option>-tpl</option>, <option>-te</option></entry>
|
|
<entry><literal>log_parser_stats = on</>,
|
|
<literal>log_planner_stats = on</>,
|
|
<literal>log_executor_stats = on</></entry>
|
|
</row>
|
|
<row>
|
|
<entry><option>-W <replaceable>x</replaceable></option></entry>
|
|
<entry><literal>post_auth_delay = <replaceable>x</replaceable></></entry>
|
|
</row>
|
|
</tbody>
|
|
</tgroup>
|
|
</table>
|
|
|
|
</sect1>
|
|
</chapter>
|