3.4. Run-time configuration

There are a lot of configuration parameters that affect the behavior of the database system in some way or other. Here we describe how to set them and the following subsections will discuss each of them.

All parameter names are case-insensitive. Every parameter takes a value of one of the four types boolean, integer, floating point, string as described below. Boolean values are ON, OFF, TRUE, FALSE, YES, NO, 1, 0 (case-insensitive) or any non-ambiguous prefix of these.

One way to set these options is to create a file postgresql.conf in the data directory (e.g., /usr/local/pgsql/data). An example of what this file could look like is:

# This is a comment
log_connections = yes
syslog = 2
As you see, options are one per line. The equal sign between name and value is optional. White space is insignificant, blank lines are ignored. Hash marks ("#") introduce comments anywhere.

The configuration file is reread whenever the postmaster receives a SIGHUP signal. This signal is also propagated to all running backend processes, so that running sessions get the new default. Alternatively, you can send the signal to only one backend process directly.

A second way to set these configuration parameters is to give them as a command line option to the postmaster, such as

postmaster -c log_connections=yes -c syslog=2
which would have the same effect as the previous example. Command-line options override any conflicting settings in postgresql.conf.

Occasionally it is also useful to give a command line option to one particular backend session only. The environment variable PGOPTIONS can be used for this purpose on the client side:

env PGOPTIONS='-c geqo=off' psql
(This works for any client application, not just psql.) Note that this won't work for options that are necessarily fixed once the server is started, such as the port number.

Finally, some options can be changed in individual SQL sessions with the SET command, for example

=> SET ENABLE_SEQSCAN TO OFF;
See the SQL command language reference for details on the syntax.

3.4.1. Planner and Optimizer Tuning

CPU_INDEX_TUPLE_COST (floating point)

Sets the query optimizer's estimate of the cost of processing each index tuple during an index scan. This is measured as a fraction of the cost of a sequential page fetch.

CPU_OPERATOR_COST (floating point)

Sets the optimizer's estimate of the cost of processing each operator in a WHERE clause. This is measured as a fraction of the cost of a sequential page fetch.

CPU_TUPLE_COST (floating point)

Sets the query optimizer's estimate of the cost of processing each tuple during a query. This is measured as a fraction of the cost of a sequential page fetch.

EFFECTIVE_CACHE_SIZE (floating point)

Sets the optimizer's assumption about the effective size of the disk cache (that is, the portion of the kernel's disk cache that will be used for Postgres data files). This is measured in disk pages, which are normally 8kB apiece.

ENABLE_HASHJOIN (boolean)

Enables or disables the query planner's use of hash-join plan types. The default is on. This is mostly useful to debug the query planner.

ENABLE_INDEXSCAN (boolean)

Enables or disables the query planner's use of index scan plan types. The default is on. This is mostly useful to debug the query planner.

ENABLE_MERGEJOIN (boolean)

Enables or disables the query planner's use of merge-join plan types. The default is on. This is mostly useful to debug the query planner.

ENABLE_NESTLOOP (boolean)

Enables or disables the query planner's use of nested-loop join plans. It's not possible to suppress nested-loop joins entirely, but turning this variable off discourages the planner from using one if there is any other method available. The default is on. This is mostly useful to debug the query planner.

ENABLE_SEQSCAN (boolean)

Enables or disables the query planner's use of sequential scan plan types. It's not possible to suppress sequential scans entirely, but turning this variable off discourages the planner from using one if there is any other method available. The default is on. This is mostly useful to debug the query planner.

ENABLE_SORT (boolean)

Enables or disables the query planner's use of explicit sort steps. It's not possible to suppress explicit sorts entirely, but turning this variable off discourages the planner from using one if there is any other method available. The default is on. This is mostly useful to debug the query planner.

ENABLE_TIDSCAN (boolean)

Enables or disables the query planner's use of TID scan plan types. The default is on. This is mostly useful to debug the query planner.

GEQO (boolean)

Enables or disables genetic query optimization, which is an algorithm that attempts to do query planning without exhaustive search. This is on by default. See also the various other GEQO_ settings.

GEQO_EFFORT (integer), GEQO_GENERATIONS (integer), GEQO_POOL_SIZE (integer), GEQO_RANDOM_SEED (integer), GEQO_SELECTION_BIAS (floating point)

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

GEQO_THRESHOLD (integer)

Use genetic query optimization to plan queries with at least this many FROM items involved. (Note that a JOIN construct counts as only one FROM item.) The default is 11. For simpler queries it is usually best to use the deterministic, exhaustive planner.

KSQO (boolean)

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

The KSQO algorithm used to be absolutely essential for queries with many OR'ed AND clauses, but in Postgres 7.0 and later the standard planner handles these queries fairly successfully. Hence the default is OFF.

RANDOM_PAGE_COST (floating point)

Sets the query optimizer's estimate of the cost of a nonsequentially fetched disk page. This is measured as a multiple of the cost of a sequential page fetch.

Note: Unfortunately, there is no well-defined method of determining ideal values for the family of "COST" variables that were just described. You are encouraged to experiment and share your findings.

3.4.2. Logging and Debugging

DEBUG_ASSERTIONS (boolean)

Turns on various assertion checks. This is a debugging aid. If you are experiencing strange problems or crashes you might want to turn this on, as it might expose programming mistakes. To use this option, the macro USE_ASSERT_CHECKING must be defined when Postgres is built (see the configure option --enable-cassert). Note that DEBUG_ASSERTIONS defaults to ON if Postgres has been built this way.

DEBUG_LEVEL (integer)

The higher this value is set, the more "debugging" output of various sorts is generated in the server log during operation. This option is 0 by default, which means no debugging output. Values up to about 4 currently make sense.

DEBUG_PRINT_PARSE (boolean), DEBUG_PRINT_PLAN (boolean), DEBUG_PRINT_REWRITTEN (boolean), DEBUG_PRINT_QUERY (boolean), DEBUG_PRETTY_PRINT (boolean)

For any executed query, prints either the query, the parse tree, the execution plan, or the query rewriter output to the server log. DEBUG_PRETTY_PRINT selects are nicer but longer output format.

HOSTNAME_LOOKUP (boolean)

By default, connection logs only show the IP address of the connecting host. If you want it to show the host name you can turn this on, but depending on your host name resolution setup it might impose a non-negligible performance penalty. This option can only be set at server start.

LOG_CONNECTIONS (boolean)

Prints a line informing about each successful connection to the server log. This is off by default, although it is probably very useful. This option can only be set at server start.

LOG_PID (boolean)

Prefixes each server log message with the process id of the backend process. This is useful to sort out which messages pertain to which connection. The default is off.

LOG_TIMESTAMP (boolean)

Prefixes each server log message with a timestamp. The default is off.

SHOW_QUERY_STATS (boolean), SHOW_PARSER_STATS (boolean), SHOW_PLANNER_STATS (boolean), SHOW_EXECUTOR_STATS (boolean)

For each query, write performance statistics of the respective module to the server log. This is a crude profiling instrument.

SHOW_SOURCE_PORT (boolean)

Shows the outgoing port number of the connecting host in the connection log messages. You could trace back the port number to find out what user initiated the connection. Other than that it's pretty useless and therefore off by default. This option can only be set at server start.

SYSLOG (integer)

Postgres allows the use of syslog for logging. If this option is set to 1, messages go both to syslog and the standard output. A setting of 2 sends output only to syslog. (Some messages will still go to the standard output/error.) The default is 0, which means syslog is off. This option must be set at server start.

To use syslog, the build of Postgres must be configured with the --enable-syslog option.

SYSLOG_FACILITY (string)

This option determines the syslog "facility" to be used when syslog is enabled. You may choose from LOCAL0, LOCAL1, LOCAL2, LOCAL3, LOCAL4, LOCAL5, LOCAL6, LOCAL7; the default is LOCAL0. See also the documentation of your system's syslog.

SYSLOG_IDENT (string)

If logging to syslog is enabled, this option determines the program name used to identify PostgreSQL messages in syslog log messages. The default is "postgres".

TRACE_NOTIFY (boolean)

Generates a great amount of debugging output for the LISTEN and NOTIFY commands.

3.4.3. General operation

DEADLOCK_TIMEOUT (integer)

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

FSYNC (boolean)

If this option is on, the Postgres backend will use the fsync() system call in several places to make sure that updates are physically written to disk and do not hang around in the kernel buffer cache. This increases the chance that a database installation will still be usable after an operating system or hardware crash by a large amount. (Crashes of the database server itself do not affect this consideration.)

However, this operation slows down Postgres, because at all those points it has to block and wait for the operating system to flush the buffers. Without fsync, the operating system is allowed to do its best in buffering, sorting, and delaying writes, which can make for a considerable perfomance increase. However, if the system crashes, the results of the last few committed transactions may be lost in part or whole; in the worst case, unrecoverable data corruption may occur.

This option is the subject of an eternal debate in the Postgres user and developer communities. Some always leave it off, some turn it off only for bulk loads, where there is a clear restart point if something goes wrong, some leave it on just to be on the safe side. Because it is the safe side, on is also the default. If you trust your operating system, your hardware, and your utility company (or better your UPS), you might want to disable fsync.

It should be noted that the performance penalty from doing fsyncs is considerably less in Postgres version 7.1 than it was in prior releases. If you previously suppressed fsyncs because of performance problems, you may wish to reconsider your choice.

This option can only be set at server start or in the postgresql.conf file.

KRB_SERVER_KEYFILE (string)

Sets the location of the Kerberos server key file. See Section 4.2.2 for details.

MAX_CONNECTIONS (integer)

Determines how many concurrent connections the database server will allow. The default is 32. There is also a compiled-in hard upper limit on this value, which is typically 1024 (both numbers can be altered when compiling the server). This parameter can only be set at server start.

MAX_EXPR_DEPTH (integer)

Sets the maximum expression nesting depth that the parser will accept. The default value is high enough for any normal query, but you can raise it if you need to. (But if you raise it too high, you run the risk of backend crashes due to stack overflow.)

PORT (integer)

The TCP port the server listens on; 5432 by default. This option can only be set at server start.

SHARED_BUFFERS (integer)

Sets the number of shared memory buffers the database server will use. The default is 64. Each buffer is typically 8192 bytes. This option can only be set at server start.

SILENT_MODE (bool)

Runs postmaster silently. If this option is set, postmaster will automatically run in background and any controlling ttys are disassociated, thus no messages are written to stdout or stderr (same effect as postmaster's -S option). Unless some logging system such as syslog is enabled, using this option is discouraged since it makes it impossible to see error messages.

SORT_MEM (integer)

Specifies the amount of memory to be used by internal sorts and hashes before resorting to temporary disk files. The value is specified in kilobytes, and defaults to 512 kilobytes. Note that for a complex query, several sorts and/or hashes might be running in parallel, and each one will be allowed to use as much memory as this value specifies before it starts to put data into temporary files. And don't forget that each running backend could be doing one or more sorts. So the total memory space needed could be many times the value of SORT_MEM.

SQL_INHERITANCE (bool)

This controls the inheritance semantics, in particular whether subtables are included into the consideration of various commands by default. This was not the case in versions prior to 7.1. If you need the old behaviour you can set this variable to off, but in the long run you are encouraged to change your applications to use the ONLY keyword to exclude subtables. See the SQL language reference and the User's Guide for more information about inheritance.

SSL (boolean)

Enables SSL connections. Please read Section 3.7 before using this. The default is off.

TCPIP_SOCKET (boolean)

If this is true, then the server will accept TCP/IP connections. Otherwise only local Unix domain socket connections are accepted. It is off by default. This option can only be set at server start.

UNIX_SOCKET_DIRECTORY (string)

Specifies the directory of the Unix-domain socket on which the postmaster is to listen for connections from client applications. The default is normally /tmp, but can be changed at build time.

UNIX_SOCKET_GROUP (string)

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

UNIX_SOCKET_PERMISSIONS (integer)

Sets the access permissions of the Unix domain socket. Unix domain sockets use the usual Unix file system permission set. The option value is expected to be an numeric mode specification in the form accepted by the chmod and umask system calls. (To use the customary octal format the number must start with a 0 (zero).)

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

This access control mechanism is independent from the one described in Chapter 4.

This option can only be set at server start.

VIRTUAL_HOST (string)

Specifies the TCP/IP hostname or address on which the postmaster is to listen for connections from client applications. Defaults to listening on all configured addresses (including localhost).

3.4.4. WAL

See also Section 9.3 for details on WAL tuning.

CHECKPOINT_SEGMENTS (integer)

Maximum distance between automatic WAL checkpoints, in logfile segments (each segment is normally 16 megabytes). This option can only be set at server start or in the postgresql.conf file.

CHECKPOINT_TIMEOUT (integer)

Maximum time between automatic WAL checkpoints, in seconds. This option can only be set at server start or in the postgresql.conf file.

WAL_BUFFERS (integer)

Number of disk-page buffers in shared memory for WAL log. This option can only be set at server start.

WAL_DEBUG (integer)

If non-zero, turn on WAL-related debugging output on standard error.

WAL_FILES (integer)

Number of log files that are created in advance at checkpoint time. This option can only be set at server start or in the postgresql.conf file.

WAL_SYNC_METHOD (string)

Method used for forcing WAL updates out to disk. Possible values are FSYNC (call fsync() at each commit), FDATASYNC (call fdatasync() at each commit), OPEN_SYNC (write WAL files with open() option O_SYNC), or OPEN_DATASYNC (write WAL files with open() option O_DSYNC). Not all of these choices are available on all platforms. This option can only be set at server start or in the postgresql.conf file.

3.4.5. Short options

For convenience there are also single letter option switches available for many parameters. They are described in the following table.

Table 3-1. Short option key

Short optionEquivalentRemark
-B xshared_buffers = x 
-d xdebug_level = x 
-Ffsync = off 
-h xvirtual_host = x 
-itcpip_socket = on 
-k xunix_socket_directory = x 
-lssl = on 
-N xmax_connections = x 
-p xport = x 
-fi, -fh, -fm, -fn, -fs, -ftenable_indexscan=off, enable_hashjoin=off, enable_mergejoin=off, enable_nestloop=off, enable_seqscan=off, enable_tidscan=off*
-S xsort_mem = x*
-sshow_query_stats = on*
-tpa, -tpl, -teshow_parser_stats=on, show_planner_stats=on, show_executor_stats=on*
For historical reasons, options marked "*" must be passed to the individual backend process via the -o postmaster option, for example,
> postmaster -o '-S 1024 -s'
or via PGOPTIONS from the client side, as explained above.