Run-time Configuration

There are a lot of configuration parameters that affect the behavior of the database system. Here we describe how to set them; 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 (for example, /usr/local/pgsql/data). An example of what this file could look like is:
# This is a comment
log_connections = yes
syslog = 2
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 will not 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.

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 PostgreSQL data files). This is measured in disk pages, which are normally 8192 bytes each.

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 is 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 an exhaustive search. This is on by default. See also the various other GEQO_ settings, which are tuning parameters for the genetic query optimization algorithm:

GEQO_EFFORT (integer)

The effort is used to calculate a default for generations. Valid values are between 1 and 80. The default is 40.

GEQO_GENERATIONS (integer)

Generations specifies the number of iterations in the algorithm. The number must be a positive integer. If 0 is specified, Effort * Log2(PoolSize) is used. The run time of the algorithm is roughly proportional to the sum of pool size and generations.

GEQO_POOL_SIZE (integer)

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.

GEQO_RANDOM_SEED (integer)

The random seed can be set to get reproducible results from the algorithm. If it is set to -1, the algorithm behaves non-deterministically.

GEQO_SELECTION_BIAS (floating point)

The selection bias is the selective pressure within the population. Values can be from 1.50 to 2.00. The default is 2.00.

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 does not 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 such as Microsoft Access, which tend to generate queries of this form. The default is OFF.

RANDOM_PAGE_COST (floating point)

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

Logging and Debugging

DEBUG_ASSERTIONS (boolean)

Turns on various assertion checks to aid in debugging. If you are experiencing strange problems or crashes, enable this option as it might expose programming mistakes. To use this option, the macro USE_ASSERT_CHECKING must be defined when PostgreSQL is built (see the configure option --enable-cassert). Note that DEBUG_ASSERTIONS defaults to ON if PostgreSQL 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. Currently, values up to about 4 are reasonable.

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

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

HOSTNAME_LOOKUP (boolean)

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

LOG_CONNECTIONS (boolean)

Prints to the server log a line informing about each successful connection. This option can be set only at server start. The default is off.

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. Its only use is to enable you to trace back the port number to find out which user initiated the connection. This option can be set only at server start. The default is off.

SYSLOG (integer)

PostgreSQL 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 PostgreSQL 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 system documentation of 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.

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 default is 1000 (that is, one second). The check for deadlock is relatively slow, so you may want to assume that deadlocks are not common in production applications. Increasing the value reduces the amount of time wasted in needless deadlock checks, but slows down reporting of real deadlock errors. Ideally the setting should exceed your typical transaction time to improve the odds that the lock will be released before the waiter decides to check for deadlock. This option can be set only at server start.

FSYNC (boolean)

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

If the fsync function is off, the operating system is allowed to buffer, sort, and delay writes, which can increase performance considerably. 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. Red Hat strongly recommends the use of the fsync function.

KRB_SERVER_KEYFILE (string)

Sets the location of the Kerberos server key file.

MAX_CONNECTIONS (integer)

Determines how many concurrent connections the database server will allow. The default is 32.

MAX_EXPR_DEPTH (integer)

Sets the maximum expression nesting depth that the parser accepts. The default value is high enough for any normal query, but you can raise it if you need to. (However, 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. The default port is 5432. This option can be set only at server start.

SHARED_BUFFERS (integer)

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

SILENT_MODE (bool)

Runs postmaster silently. If this option is set, postmaster automatically runs in the background and any controlling ttys are disassociated, thus no messages are written to stdout or stderr. (This is the same effect as the postmaster program'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 (in kilobytes) that can be used per sort for internal sorts and hashes before temporary disk files are used. The default value is 512. 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. 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.

SSL (boolean)

Enables SSL connections. Please read the section "Secure TCP/IP Connections with SSL" 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. The default is off. This option can be set only 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 /tmp, but can be changed at build time.

UNIX_SOCKET_GROUP (string)

Sets the group owner of the UNIX-domain socket. In combination with the UNIX_SOCKET_PERMISSIONS option, this can be used as an additional access control mechanism for this socket type. By default this is the empty string, which uses the default group for the current user. This option can be set only 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 a 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). This option can be set only at server start. This access control mechanism is independent from the one described in the chapter "Client Authentication".

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).

Write-Ahead Logging (WAL)

See also "WAL Configuration" 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, which can be set in the postgresql.conf file, can be set only at server start.

CHECKPOINT_TIMEOUT (integer)

Maximum time between automatic WAL checkpoints, in seconds.

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

COMMIT_DELAY (integer)

The time delay between writing a commit record to the WAL buffer and flushing the buffer to disk, in microseconds. A non-zero delay enables multiple transactions to be committed with only one fsync if the system load is high enough that additional transactions become ready to commit within the given interval. The delay is performed only if at least COMMIT_SIBLINGS other transactions are active at the instant that a backend has written its commit record.

COMMIT_SIBLINGS (integer)

The minimum number of concurrent open transactions required before performing the 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.

WAL_BUFFERS (integer)

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

WAL_DEBUG (integer)

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

WAL_FILES (integer)

Number of log files that are created in advance at checkpoint time.

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

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). This option, which can be set in the postgresql.conf file, can be set only at server start.

Short Options

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

Table 1-1. Short Option Keys

Short OptionEquivalentRemarks
-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*
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 previously.