Improve documentation around parameter-setting and ALTER SYSTEM.

The ALTER SYSTEM ref page hadn't been held to a very high standard, nor
was the feature well integrated into section 18.1 (parameter setting).
Also, though commit 4c4654afe had improved the structure of 18.1, it also
introduced a lot of poor wording, imprecision, and outright falsehoods.
Try to clean that up.
This commit is contained in:
Tom Lane 2014-12-14 18:09:51 -05:00
parent 0923b01e3e
commit af06aa822d
2 changed files with 227 additions and 186 deletions

View File

@ -23,15 +23,16 @@
<para>
All parameter names are case-insensitive. Every parameter takes a
value of one of five types: boolean, integer, floating point,
string, or enum.
value of one of five types: boolean, string, integer, floating point,
or enumerated (enum). The type determines the syntax for setting the
parameter:
</para>
<itemizedlist>
<listitem>
<para>
<emphasis>Boolean:</emphasis> Values can be written as
<emphasis>Boolean:</emphasis>
Values can be written as
<literal>on</literal>,
<literal>off</literal>,
<literal>true</literal>,
@ -40,37 +41,42 @@
<literal>no</literal>,
<literal>1</literal>,
<literal>0</literal>
(all case-insensitive) or any unambiguous prefix of these.
(all case-insensitive) or any unambiguous prefix of one of these.
</para>
</listitem>
<listitem>
<para>
<emphasis>String:</emphasis> Enclose the value in
single-quotes. Values are case-insensitive. If multiple values
are allowed, separate them with commas.
<emphasis>String:</emphasis>
In general, enclose the value in single quotes, doubling any single
quotes within the value. Quotes can usually be omitted if the value
is a simple number or identifier, however.
</para>
</listitem>
<listitem>
<para>
<emphasis>Numeric (integer and floating point):</emphasis> Do
not use single-quotes (unless otherwise required) or thousand
separators.
<emphasis>Numeric (integer and floating point):</emphasis>
A decimal point is permitted only for floating-point parameters.
Do not use thousands separators. Quotes are not required.
</para>
</listitem>
<listitem>
<para>
<emphasis>Numeric or String with Unit (Memory &amp;
Time):</emphasis> These have an implicit unit, which is
either kilobytes, blocks (typically eight kilobytes),
milliseconds, seconds, or minutes. A unadorned numeric
value will use the default, which can be found by referencing
<structname>pg_settings</>.<structfield>unit</>. For convenience,
a different unit can also be specified explicitly via a string
value. It is case-sensitive and may include whitespace between
the value and the unit.
<emphasis>Numeric with Unit:</emphasis>
Some numeric parameters have an implicit unit, because they describe
quantities of memory or time. The unit might be kilobytes, blocks
(typically eight kilobytes), milliseconds, seconds, or minutes.
An unadorned numeric value for one of these settings will use the
setting's default unit, which can be learned from
<structname>pg_settings</>.<structfield>unit</>.
For convenience, settings can be given with a unit specified explicitly,
for example <literal>'120 ms'</> for a time value, and they will be
converted to whatever the parameter's actual unit is. Note that the
value must be written as a string (with quotes) to use this feature.
The unit name is case-sensitive, and there can be whitespace between
the numeric value and the unit.
<itemizedlist>
<listitem>
@ -81,7 +87,7 @@
The multiplier for memory units is 1024, not 1000.
</para>
</listitem>
<listitem>
<para>
Valid time units are <literal>ms</literal> (milliseconds),
@ -95,13 +101,11 @@
<listitem>
<para>
<emphasis><quote>enum</>:</emphasis> These are specified
in the same way as string parameters, but are restricted
to a limited set of values that can be queried from
<structname>pg_settings</>.<structfield>enumvals</>:
<programlisting>
SELECT name, setting, enumvals FROM pg_settings WHERE enumvals IS NOT NULL;
</programlisting>
<emphasis>Enumerated:</emphasis>
Enumerated-type parameters are written in the same way as string
parameters, but are restricted to have one of a limited set of
values. The values allowable for such a parameter can be found from
<structname>pg_settings</>.<structfield>enumvals</>.
Enum parameter values are case-insensitive.
</para>
</listitem>
@ -109,13 +113,13 @@ SELECT name, setting, enumvals FROM pg_settings WHERE enumvals IS NOT NULL;
</sect2>
<sect2 id="config-setting-configuration-file">
<title>Parameter Interaction via Configuration File</title>
<title>Parameter Interaction via the Configuration File</title>
<para>
The primary way to set these parameters is to edit the file
The most fundamental 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 when the database cluster directory is initialized.)
which is normally kept in the data directory. A default copy is
installed when the database cluster directory is initialized.
An example of what this file might look like is:
<programlisting>
# This is a comment
@ -125,81 +129,96 @@ 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
value is optional. Whitespace is insignificant (except within a quoted
parameter value) and blank lines are
ignored. Hash marks (<literal>#</literal>) designate the remainder
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)
quote in a parameter value, write either two quotes (preferred)
or backslash-quote.
</para>
<para>
Parameters set in this way provide default values for the cluster.
The setting seen by active sessions will be this value unless
it is overridden. The following sections describe ways in which the
The settings seen by active sessions will be these values unless they
are overridden. The following sections describe ways in which the
administrator or user can override these defaults.
</para>
<para>
<indexterm>
<primary>SIGHUP</primary>
<primary>SIGHUP</primary>
</indexterm>
The configuration file is reread whenever the main server process
receives a <systemitem>SIGHUP</> signal; this is most easily done by
running <literal>pg_ctl reload</> from the command-line or by calling
the SQL function <function>pg_reload_conf()</function>. The main
receives a <systemitem>SIGHUP</> signal; this signal is most easily
sent by running <literal>pg_ctl reload</> from the command line or by
calling the SQL function <function>pg_reload_conf()</function>. The main
server process also propagates this signal to all currently running
server processes so that existing sessions also get the new value
when they complete their transactions. Alternatively, you can
server processes, so that existing sessions also adopt the new values
(this will happen after they complete any currently-executing client
command). 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>
In addition to <filename>postgresql.conf</>,
a <productname>PostgreSQL</productname> data directory contains a file
<filename>postgresql.auto.conf</><indexterm><primary>postgresql.auto.conf</></>,
which has the same format as <filename>postgresql.conf</> but should
never be edited manually. This file holds settings provided through
the <xref linkend="SQL-ALTERSYSTEM"> command. This file is automatically
read whenever <filename>postgresql.conf</> is, and its settings take
effect in the same way. Settings in <filename>postgresql.auto.conf</>
override those in <filename>postgresql.conf</>.
</para>
</sect2>
<sect2 id="config-setting-sql-command-interaction">
<title>Parameter Interaction via SQL</title>
<para>
<productname>PostgreSQL</productname> provides three SQL
commands to establish configuration defaults that override those
configured globally. The evaluation of these defaults occurs
at the beginning of a new session, upon the user issuing <xref
linkend="SQL-DISCARD">, or if the server forces the session to
reload its configuration after a <systemitem>SIGHUP</systemitem>
signal.
<productname>PostgreSQL</productname> provides three SQL
commands to establish configuration defaults.
The already-mentioned <xref linkend="SQL-ALTERSYSTEM"> command
provides a SQL-accessible means of changing global defaults; it is
functionally equivalent to editing <filename>postgresql.conf</>.
In addition, there are two commands that allow setting of defaults
on a per-database or per-role basis:
</para>
<itemizedlist>
<listitem>
<para>
The <xref linkend="SQL-ALTERSYSTEM"> command provides an
SQL-accessible means of changing global defaults.
<listitem>
<para>
The <xref linkend="sql-alterdatabase"> command allows global
settings to be overridden on a per-database basis.
</para>
</listitem>
<listitem>
<para>
The <xref linkend="sql-alterdatabase"> command allows database
administrators to override global settings on a per-database basis.
</para>
</listitem>
<listitem>
<para>
The <xref linkend="sql-alterrole"> command allows database
administrators to override both global and per-database settings
with user-specific values.
The <xref linkend="sql-alterrole"> command allows both global and
per-database settings to be overridden with user-specific values.
</para>
</listitem>
</itemizedlist>
<para>
Once a client connects to the database PostgreSQL provides
two additional SQL commands to interact with session-local
configuration settings. Both of these commands have equivalent
system administration functions.
Values set with <command>ALTER DATABASE</> and <command>ALTER ROLE</>
are applied only when starting a fresh database session. They
override values obtained from the configuration files or server
command line, and constitute defaults for the rest of the session.
Note that some settings cannot be changed after server start, and
so cannot be set with these commands (or the ones listed below).
</para>
<para>
Once a client is connected to the database, <productname>PostgreSQL</>
provides two additional SQL commands (and equivalent functions) to
interact with session-local configuration settings:
</para>
<itemizedlist>
@ -214,49 +233,50 @@ shared_buffers = 128MB
<listitem>
<para>
The <xref linkend="SQL-SET"> command allows modification of the
current value of some parameters. The corresponding function is
current value of those parameters that can be set locally to a
session; it has no effect on other sessions.
The corresponding function is
<function>set_config(setting_name, new_value, is_local)</function>.
</para>
</listitem>
</itemizedlist>
<para>
Both <command>SELECT</> and <command>UPDATE</>
can be issued against the system view <link
linkend="view-pg-settings"><structname>pg_settings</></> to view
and change session-local values.
In addition, the system view <link
linkend="view-pg-settings"><structname>pg_settings</></> can be
used to view and change session-local values:
</para>
<itemizedlist>
<listitem>
<para>
Querying this view is the same as <command>SHOW</> but provides
more detail, as well as allowing for joins against other relations
and the specification of filter criteria.
Querying this view is similar to using <command>SHOW ALL</> but
provides more detail. It is also more flexible, since it's possible
to specify filter conditions or join against other relations.
</para>
</listitem>
<listitem>
<para>
Using <xref linkend="SQL-UPDATE"> on this relation, specifically
<listitem>
<para>
Using <xref linkend="SQL-UPDATE"> on this view, specifically
updating the <structname>setting</> column, is the equivalent
of issuing SQL <command>SET</>, though all values must be
single-quoted. Note that the equivalent of
of issuing <command>SET</> commands. For example, the equivalent of
<programlisting>
SET configuration_parameter TO DEFAULT;
</>
is:
</programlisting>
is:
<programlisting>
UPDATE pg_settings SET setting = reset_val WHERE name = 'configuration_parameter';
</programlisting>
</para>
</listitem>
</itemizedlist>
</para>
</listitem>
</itemizedlist>
</sect2>
<sect2>
<title>Parameter Interaction via Shell</title>
<title>Parameter Interaction via the Shell</title>
<para>
In addition to setting global defaults or attaching
overrides at the database or role level, you can pass settings to
@ -268,41 +288,38 @@ UPDATE pg_settings SET setting = reset_val WHERE name = 'configuration_parameter
<itemizedlist>
<listitem>
<para>
On the <emphasis>server</emphasis>, command-line options can be
passed to the <command>postgres</command> command directly via the
<option>-c</> parameter.
During server startup, parameter settings can be
passed to the <command>postgres</command> command via the
<option>-c</> command-line parameter. For example,
<programlisting>
postgres -c log_connections=yes -c log_destination='syslog'
</programlisting>
Settings provided this way override those resolved globally (via
<filename>postgresql.conf</> or <command>ALTER SYSTEM</>) but
are otherwise treated as being global for the purpose of database
and role overrides.
Settings provided in this way override those set via
<filename>postgresql.conf</> or <command>ALTER SYSTEM</>,
so they cannot be changed globally without restarting the server.
</para>
</listitem>
<listitem>
<para>
On the <emphasis>libpq-client</emphasis>, command-line options can be
When starting a client session via <application>libpq</>,
parameter settings can be
specified using the <envar>PGOPTIONS</envar> environment variable.
When connecting to the server, the contents of this variable are
sent to the server as if they were being executed via SQL <xref
linkend="SQL-SET"> at the beginning of the session.
</para>
<para>
However, the format of <envar>PGOPTIONS</envar> is similar to that
used when launching the <command>postgres</command> command.
Specifically, the <option>-c</> flag must be specified.
Settings established in this way constitute defaults for the life
of the session, but do not affect other sessions.
For historical reasons, the format of <envar>PGOPTIONS</envar> is
similar to that used when launching the <command>postgres</command>
command; specifically, the <option>-c</> flag must be specified.
For example,
<programlisting>
env PGOPTIONS="-c geqo=off -c statement_timeout='5 min'" psql
env PGOPTIONS="-c geqo=off -c statement_timeout=5min" psql
</programlisting>
</para>
<para>
Other clients and libraries might provide their own mechanisms,
via the shell or otherwise, that allow the user to alter session
settings without requiring the user to issue SQL commands.
settings without direct use of SQL commands.
</para>
</listitem>
</itemizedlist>
@ -310,25 +327,32 @@ env PGOPTIONS="-c geqo=off -c statement_timeout='5 min'" psql
</sect2>
<sect2 id="config-includes">
<title>Configuration File Includes</title>
<title>Managing Configuration File Contents</title>
<para>
<productname>PostgreSQL</> provides several features for breaking
down complex <filename>postgresql.conf</> files into sub-files.
These features are especially useful when managing multiple servers
with related, but not identical, configurations.
</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. This feature allows a configuration
file to be divided into physically separate parts.
Include directives simply look like:
</indexterm>
In addition to individual 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. This
feature allows a configuration file to be divided into physically
separate parts. 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.
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>
@ -336,12 +360,12 @@ include 'filename'
<primary><literal>include_if_exists</></primary>
<secondary>in configuration file</secondary>
</indexterm>
There is also an <literal>include_if_exists</> directive, which acts
the same as the <literal>include</> directive, except for the behavior
when the referenced file does not exist or cannot be read. A regular
<literal>include</> will consider this an error condition, but
<literal>include_if_exists</> merely logs a message and continues
processing the referencing configuration file.
There is also an <literal>include_if_exists</> directive, which acts
the same as the <literal>include</> directive, except
when the referenced file does not exist or cannot be read. A regular
<literal>include</> will consider this an error condition, but
<literal>include_if_exists</> merely logs a message and continues
processing the referencing configuration file.
</para>
<para>
@ -349,79 +373,83 @@ include 'filename'
<primary><literal>include_dir</></primary>
<secondary>in configuration file</secondary>
</indexterm>
The <filename>postgresql.conf</> file can also contain
<literal>include_dir</literal> directives, which specify an entire directory
of configuration files to include. It is used similarly:
The <filename>postgresql.conf</> file can also contain
<literal>include_dir</literal> directives, which specify an entire
directory of configuration files to include. These look like
<programlisting>
include_dir 'directory'
</programlisting>
Non-absolute directory names follow the same rules as single file include
directives: they are relative to the directory containing the referencing
configuration file. Within that directory, only non-directory files whose
names end with the suffix <literal>.conf</literal> will be included. File
names that start with the <literal>.</literal> character are also excluded,
to prevent mistakes as they are hidden on some platforms. Multiple files
within an include directory are processed in file name order. The file names
are ordered by C locale rules, i.e. numbers before letters, and uppercase
letters before lowercase ones.
Non-absolute directory names are taken as relative to the directory
containing the referencing configuration file. Within the specified
directory, only non-directory files whose names end with the
suffix <literal>.conf</literal> will be included. File names that
start with the <literal>.</literal> character are also ignored, to
prevent mistakes since such files are hidden on some platforms. Multiple
files within an include directory are processed in file name order
(according to C locale rules, i.e. numbers before letters, and
uppercase letters before lowercase ones).
</para>
<para>
Include files or directories can be used to logically separate portions
of the database configuration, rather than having a single large
<filename>postgresql.conf</> file. Consider a company that has two
database servers, each with a different amount of memory. There are likely
elements of the configuration both will share, for things such as logging.
But memory-related parameters on the server will vary between the two. And
there might be server specific customizations, too. One way to manage this
situation is to break the custom configuration changes for your site into
three files. You could add this to the end of your
<filename>postgresql.conf</> file to include them:
Include files or directories can be used to logically separate portions
of the database configuration, rather than having a single large
<filename>postgresql.conf</> file. Consider a company that has two
database servers, each with a different amount of memory. There are
likely elements of the configuration both will share, for things such
as logging. But memory-related parameters on the server will vary
between the two. And there might be server specific customizations,
too. One way to manage this situation is to break the custom
configuration changes for your site into three files. You could add
this to the end of your <filename>postgresql.conf</> file to include
them:
<programlisting>
include 'shared.conf'
include 'memory.conf'
include 'server.conf'
</programlisting>
All systems would have the same <filename>shared.conf</>. Each server
with a particular amount of memory could share the same
<filename>memory.conf</>; you might have one for all servers with 8GB of RAM,
another for those having 16GB. And finally <filename>server.conf</> could
have truly server-specific configuration information in it.
All systems would have the same <filename>shared.conf</>. Each
server with a particular amount of memory could share the
same <filename>memory.conf</>; you might have one for all servers
with 8GB of RAM, another for those having 16GB. And
finally <filename>server.conf</> could have truly server-specific
configuration information in it.
</para>
<para>
Another possibility is to create a configuration file directory and
put this information into files there. For example, a <filename>conf.d</>
directory could be referenced at the end of<filename>postgresql.conf</>:
Another possibility is to create a configuration file directory and
put this information into files there. For example, a <filename>conf.d</>
directory could be referenced at the end of <filename>postgresql.conf</>:
<programlisting>
include_dir 'conf.d'
</programlisting>
Then you could name the files in the <filename>conf.d</> directory like this:
Then you could name the files in the <filename>conf.d</> directory
like this:
<programlisting>
00shared.conf
01memory.conf
02server.conf
</programlisting>
This shows a clear order in which these files will be loaded. This is
important because only the last setting encountered when the server is
reading its configuration will be used. Something set in
<filename>conf.d/02server.conf</> in this example would override a value
set in <filename>conf.d/01memory.conf</>.
This naming convention establishes a clear order in which these
files will be loaded. This is important because only the last
setting encountered for a particular parameter while the server is
reading configuration files will be used. In this example,
something set in <filename>conf.d/02server.conf</> would override a
value set in <filename>conf.d/01memory.conf</>.
</para>
<para>
You might instead use this configuration directory approach while naming
these files more descriptively:
You might instead use this approach to naming the files
descriptively:
<programlisting>
00shared.conf
01memory-8GB.conf
02server-foo.conf
</programlisting>
This sort of arrangement gives a unique name for each configuration file
variation. This can help eliminate ambiguity when several servers have
their configurations all stored in one place, such as in a version
control repository. (Storing database configuration files under version
control is another good practice to consider).
This sort of arrangement gives a unique name for each configuration file
variation. This can help eliminate ambiguity when several servers have
their configurations all stored in one place, such as in a version
control repository. (Storing database configuration files under version
control is another good practice to consider.)
</para>
</sect2>
</sect1>

View File

@ -32,23 +32,30 @@ ALTER SYSTEM RESET ALL
<title>Description</title>
<para>
<command>ALTER SYSTEM</command> writes the configuration parameter
values to the <filename>postgresql.auto.conf</filename> file.
Setting the parameter to <literal>DEFAULT</literal>, or using the
<command>RESET</command> variant, removes the configuration entry from
<command>ALTER SYSTEM</command> is used for changing server configuration
parameters across the entire database cluster. It can be more convenient
than the traditional method of manually editing
the <filename>postgresql.conf</filename> file.
<command>ALTER SYSTEM</command> writes the given parameter setting to
the <filename>postgresql.auto.conf</filename> file, which is read in
addition to <filename>postgresql.conf</filename>.
Setting a parameter to <literal>DEFAULT</literal>, or using the
<command>RESET</command> variant, removes that configuration entry from the
<filename>postgresql.auto.conf</filename> file. Use <literal>RESET
ALL</literal> to clear all configuration entries. The values will
be effective after reload of server configuration (SIGHUP) or in next
server start based on the type of configuration parameter modified.
ALL</literal> to remove all such configuration entries.
</para>
<para>
This command is not allowed inside transaction block or function.
Values set with <command>ALTER SYSTEM</command> will be effective after
the next server configuration reload (<systemitem>SIGHUP</>
or <literal>pg_ctl reload</>), or after the next server restart in the
case of parameters that can only be changed at server start.
</para>
<para>
See <xref linkend="config-setting"> for other ways to set the parameters and
how they become effective.
Only superusers can use <command>ALTER SYSTEM</command>. Also, since
this command acts directly on the file system and cannot be rolled back,
it is not allowed inside a transaction block or function.
</para>
</refsect1>
@ -60,7 +67,7 @@ ALTER SYSTEM RESET ALL
<term><replaceable class="parameter">configuration_parameter</replaceable></term>
<listitem>
<para>
Name of a settable run-time parameter. Available parameters are
Name of a settable configuration parameter. Available parameters are
documented in <xref linkend="runtime-config">.
</para>
</listitem>
@ -70,11 +77,11 @@ ALTER SYSTEM RESET ALL
<term><replaceable class="parameter">value</replaceable></term>
<listitem>
<para>
New value of parameter. Values can be specified as string
New value of the parameter. Values can be specified as string
constants, identifiers, numbers, or comma-separated lists of
these, as appropriate for the particular parameter.
<literal>DEFAULT</literal> can be written to specify to remove the
parameter and its value from <filename>postgresql.auto.conf</filename>
<literal>DEFAULT</literal> can be written to specify removing the
parameter and its value from <filename>postgresql.auto.conf</filename>.
</para>
</listitem>
</varlistentry>
@ -85,12 +92,16 @@ ALTER SYSTEM RESET ALL
<title>Notes</title>
<para>
This command can't be used to set <xref linkend="guc-data-directory">
and any parameters (e.g., <link linkend="runtime-config-preset">preset options</>)
that are not allowed in <filename>postgresql.conf</>.
This command can't be used to set <xref linkend="guc-data-directory">,
nor parameters that are not allowed in <filename>postgresql.conf</>
(e.g., <link linkend="runtime-config-preset">preset options</>).
</para>
<para>
See <xref linkend="config-setting"> for other ways to set the parameters.
</para>
</refsect1>
<refsect1>
<title>Examples</title>
@ -102,10 +113,12 @@ ALTER SYSTEM SET wal_level = hot_standby;
</para>
<para>
Set the <literal>authentication_timeout</>:
Undo that, restoring whatever setting was effective
in <filename>postgresql.conf</>:
<programlisting>
ALTER SYSTEM SET authentication_timeout = 10;
</programlisting></para>
ALTER SYSTEM RESET wal_level;
</programlisting>
</para>
</refsect1>
<refsect1>