PostgreSQL 7.4.8 Documentation | ||||
---|---|---|---|---|
Prev | Fast Backward | Chapter 16. Server Run-time Environment | Fast Forward | Next |
There are a lot of configuration parameters that affect the behavior of the database system. In this subsection, we describe how to set configuration parameters; the following subsections discuss each parameter in detail.
All parameter names are case-insensitive. Every parameter takes a value of one of the four types: boolean, integer, floating point, and string. 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 parameters is to edit the file postgresql.conf in the data directory. (A default file is installed there.) An example of what this file might look like is:
# This is a comment log_connections = yes syslog = 2 search_path = '$user, public'
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 (#) introduce comments anywhere. Parameter values that are not simple identifiers or numbers should be single-quoted.
The configuration file is reread whenever the postmaster process receives a SIGHUP signal (which is most easily sent by means of pg_ctl reload). The postmaster 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.
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
Command-line options override any conflicting settings in postgresql.conf.
Occasionally it is also useful to give a command line option to one particular 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 libpq-based client application, not just psql.) Note that this won't work for parameters that are fixed when the server is started, such as the port number.
Furthermore, it is possible to assign a set of option settings to a user or a database. Whenever a session is started, the default settings for the user and database involved are loaded. The commands ALTER DATABASE and ALTER USER, respectively, are used to configure these settings. Per-database settings override anything received from the postmaster command-line or the configuration file, and in turn are overridden by per-user settings; both are overridden by per-session options.
Some parameters can be changed in individual SQL sessions with the SET command, for example:
SET ENABLE_SEQSCAN TO OFF;
If SET is allowed, it overrides all other sources of values for the parameter. Superusers are allowed to SET more values than ordinary users.
The SHOW command allows inspection of the current values of all parameters.
The virtual table pg_settings (described in Section 43.34) also allows displaying and updating session run-time parameters. It is equivalent to SHOW and SET, but can be more convenient to use because it can be joined with other tables, or selected from using any desired selection condition.
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.
Determines the maximum number of concurrent connections to the database server. The default is typically 100, but may be less if your kernel settings will not support it (as determined during initdb). This parameter can only be set at server start.
Increasing this parameter may cause PostgreSQL to request more System V shared memory or semaphores than your operating system's default configuration allows. See Section 16.5.1 for information on how to adjust these parameters, if necessary.
Determines the number of "connection slots" that are reserved for connections by PostgreSQL superusers. At most max_connections connections can ever be active simultaneously. Whenever the number of active concurrent connections is at least max_connections minus superuser_reserved_connections, new connections will be accepted only for superusers.
The default value is 2. The value must be less than the value of max_connections. This parameter can only be set at server start.
The TCP port the server listens on; 5432 by default. This option can only be set at server start.
Specifies the directory of the Unix-domain socket on which the server is to listen for connections from client applications. The default is normally /tmp, but can be changed at build time.
Sets the group owner of the Unix domain socket. (The owning user of the socket is always the user that starts the server.) 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.
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 are 0770 (only user and group, see also under unix_socket_group) and 0700 (only user). (Note that actually for a Unix domain socket, only write permission matters and there is no point in setting or revoking read or execute permissions.)
This access control mechanism is independent of the one described in Chapter 19.
This option can only be set at server start.
Specifies the host name or IP address on which the server is to listen for connections from client applications. The default is to listen on all configured addresses (including localhost).
Specifies the Rendezvous broadcast name. By default, the computer name is used, specified as ''.
Maximum time to complete client authentication, in seconds. If a would-be client has not completed the authentication protocol in this much time, the server breaks the connection. This prevents hung clients from occupying a connection indefinitely. This option can only be set at server start or in the postgresql.conf file. The default is 60.
Enables SSL connections. Please read Section 16.7 before using this. The default is off.
When a password is specified in CREATE USER or ALTER USER without writing either ENCRYPTED or UNENCRYPTED, this option determines whether the password is to be encrypted. The default is on (encrypt the password).
Sets the location of the Kerberos server key file. See Section 19.2.3 for details.
This allows per-database user names. It is off by default.
If this is on, you should create users as username@dbname. When username is passed by a connecting client, @ and the database name is appended to the user name and that database-specific user name is looked up by the server. Note that when you create users with names containing @ within the SQL environment, you will need to quote the user name.
With this option enabled, you can still create ordinary global users. Simply append @ when specifying the user name in the client. The @ will be stripped off before the user name is looked up by the server.
Note: This feature is intended as a temporary measure until a complete solution is found. At that time, this option will be removed.
Sets the number of shared memory buffers used by the database server. The default is typically 1000, but may be less if your kernel settings will not support it (as determined during initdb). Each buffer is 8192 bytes, unless a different value of BLCKSZ was chosen when building the server. This setting must be at least 16, as well as at least twice the value of max_connections; however, settings significantly higher than the minimum are usually needed for good performance. Values of a few thousand are recommended for production installations. This option can only be set at server start.
Increasing this parameter may cause PostgreSQL to request more System V shared memory than your operating system's default configuration allows. See Section 16.5.1 for information on how to adjust these parameters, if necessary.
Specifies the amount of memory to be used by internal sort operations and hash tables before switching to temporary disk files. The value is specified in kilobytes, and defaults to 1024 kilobytes (1 MB). Note that for a complex query, several sort or hash operations might be running in parallel; each one will be allowed to use as much memory as this value specifies before it starts to put data into temporary files. Also, several running sessions could be doing sort operations simultaneously. So the total memory used could be many times the value of sort_mem. Sort operations are used by ORDER BY, merge joins, and CREATE INDEX. Hash tables are used in hash joins, hash-based aggregation, and hash-based processing of IN subqueries. Because CREATE INDEX is used when restoring a database, increasing sort_mem before doing a large restore operation can improve performance.
Specifies the maximum amount of memory to be used by VACUUM to keep track of to-be-reclaimed rows. The value is specified in kilobytes, and defaults to 8192 kB. Larger settings may improve the speed of vacuuming large tables that have many deleted rows.
Sets the maximum number of disk pages for which free space will be tracked in the shared free-space map. Six bytes of shared memory are consumed for each page slot. This setting must be more than 16 * max_fsm_relations. The default is 20000. This option can only be set at server start.
Sets the maximum number of relations (tables and indexes) for which free space will be tracked in the shared free-space map. Roughly fifty bytes of shared memory are consumed for each slot. The default is 1000. This option can only be set at server start.
Sets the maximum number of simultaneously open files allowed to each server subprocess. The default is 1000. If the kernel is enforcing a safe per-process limit, you don't need to worry about this setting. But on some platforms (notably, most BSD systems), the kernel will allow individual processes to open many more files than the system can really support when a large number of processes all try to open that many files. If you find yourself seeing "Too many open files" failures, try reducing this setting. This option can only be set at server start.
This variable specifies one or more shared libraries that are to be preloaded at server start. A parameterless initialization function can optionally be called for each library. To specify that, add a colon and the name of the initialization function after the library name. For example '$libdir/mylib:mylib_init' would cause mylib to be preloaded and mylib_init to be executed. If more than one library is to be loaded, separate their names with commas.
If mylib or mylib_init are not found, the server will fail to start.
PostgreSQL procedural language libraries may be preloaded in this way, typically by using the syntax '$libdir/plXXX:plXXX_init' where XXX is pgsql, perl, tcl, or python.
By preloading a shared library (and initializing it if applicable), the library startup time is avoided when the library is first used. However, the time to start each new server process may increase, even if that process never uses the library.
See also Section 25.3 for details on WAL tuning.
If this option is on, the PostgreSQL server
will use the fsync()
system call in several places
to make sure that updates are physically written to disk. This
insures that a database cluster will recover to a
consistent state after an operating system or hardware crash.
(Crashes of the database server itself are not
related to this.)
However, using fsync()
results in a
performance penalty: when a transaction is committed,
PostgreSQL must wait for the
operating system to flush the write-ahead log to disk. When
fsync is disabled, the operating system is
allowed to do its best in buffering, ordering, and delaying
writes. This can result in significantly improved performance.
However, if the system crashes, the results of the last few
committed transactions may be lost in part or whole. In the
worst case, unrecoverable data corruption may occur.
Due to the risks involved, there is no universally correct setting for fsync. Some administrators always disable fsync, while others only turn it off for bulk loads, where there is a clear restart point if something goes wrong, whereas some administrators always leave fsync enabled. The default is to enable fsync, for maximum reliability. If you trust your operating system, your hardware, and your utility company (or your battery backup), you can consider disabling fsync.
This option can only be set at server start or in the postgresql.conf file.
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), and
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.
Number of disk-page buffers in shared memory for WAL logging. The default is 8. This option can only be set at server start.
Maximum distance between automatic WAL checkpoints, in log file segments (each segment is normally 16 megabytes). The default is three. This option can only be set at server start or in the postgresql.conf file.
Maximum time between automatic WAL checkpoints, in seconds. The default is 300 seconds. This option can only be set at server start or in the postgresql.conf file.
Write a message to the server logs if checkpoints caused by the filling of checkpoint segment files happens more frequently than this number of seconds. The default is 30 seconds. Zero turns off the warning.
Time delay between writing a commit record to the WAL buffer
and flushing the buffer out to disk, in microseconds. A
nonzero delay allows multiple transactions to be committed
with only one fsync()
system call, if
system load is high enough additional transactions may 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
commit_siblings other transactions are
active at the instant that a server process has written its
commit record. The default is zero (no delay).
Minimum number of concurrent open transactions to require 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. The default is five.
Note: These configuration parameters provide a crude method for influencing the query plans chosen by the query optimizer. If the default plan chosen by the optimizer for a particular query is not optimal, a temporary solution may be found by using one of these configuration parameters to force the optimizer to choose a better plan. Other ways to improve the quality of the plans chosen by the optimizer include configuring the Planner Cost Constants, running ANALYZE more frequently, and increasing the amount of statistics collected for a particular column using ALTER TABLE SET STATISTICS.
Enables or disables the query planner's use of hashed aggregation plan types. The default is on. This is used for debugging the query planner.
Enables or disables the query planner's use of hash-join plan types. The default is on. This is used for debugging the query planner.
Enables or disables the query planner's use of index-scan plan types. The default is on. This is used for debugging the query planner.
Enables or disables the query planner's use of merge-join plan types. The default is on. This is used for debugging the query planner.
Enables or disables the query planner's use of nested-loop join plans. It's not possible to suppress nested-loop joins entirely, but turning this variable off discourages the planner from using one if there are other methods available. The default is on. This is used for debugging the query planner.
Enables or disables the query planner's use of sequential scan plan types. It's not possible to suppress sequential scans entirely, but turning this variable off discourages the planner from using one if there are other methods available. The default is on. This is used for debugging the query planner.
Enables or disables the query planner's use of explicit sort steps. It's not possible to suppress explicit sorts entirely, but turning this variable off discourages the planner from using one if there are other methods available. The default is on. This is used for debugging the query planner.
Enables or disables the query planner's use of TID scan plan types. The default is on. This is used for debugging the query planner.
Note: Unfortunately, there is no well-defined method for determining ideal values for the family of "cost" variables that appear below. You are encouraged to experiment and share your findings.
Sets the planner'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. The default is 1000.
Sets the query planner's estimate of the cost of a nonsequentially fetched disk page. This is measured as a multiple of the cost of a sequential page fetch. A higher value makes it more likely a sequential scan will be used, a lower value makes it more likely an index scan will be used. The default is four.
Sets the query planner's estimate of the cost of processing each row during a query. This is measured as a fraction of the cost of a sequential page fetch. The default is 0.01.
Sets the query planner's estimate of the cost of processing each index row during an index scan. This is measured as a fraction of the cost of a sequential page fetch. The default is 0.001.
Sets the planner'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. The default is 0.0025.
Enables or disables genetic query optimization, which is an algorithm that attempts to do query planning without exhaustive searching. This is on by default. See also the various other geqo_ settings.
Use genetic query optimization to plan queries with at least this many FROM items involved. (Note that an outer 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, but for queries with many tables the deterministic planner takes too long.
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.
Sets the default statistics target for table columns that have not had a column-specific target set via ALTER TABLE SET STATISTICS. Larger values increase the time needed to do ANALYZE, but may improve the quality of the planner's estimates. The default is 10.
The planner will merge sub-queries into upper queries if the resulting FROM list would have no more than this many items. Smaller values reduce planning time but may yield inferior query plans. The default is 8. It is usually wise to keep this less than geqo_threshold.
The planner will flatten explicit inner JOIN constructs into lists of FROM items whenever a list of no more than this many items would result. Usually this is set the same as from_collapse_limit. Setting it to 1 prevents any flattening of inner JOINs, allowing explicit JOIN syntax to be used to control the join order. Intermediate values might be useful to trade off planning time against quality of plan.
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.
This option determines the syslog "facility" to be used when logging via 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.
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.
Controls which message levels are sent to the client. Valid values are DEBUG5, DEBUG4, DEBUG3, DEBUG2, DEBUG1, LOG, NOTICE, WARNING, and ERROR. Each level includes all the levels that follow it. The later the level, the fewer messages are sent. The default is NOTICE. Note that LOG has a different rank here than in log_min_messages.
Controls which message levels are written to the server log. Valid values are DEBUG5, DEBUG4, DEBUG3, DEBUG2, DEBUG1, INFO, NOTICE, WARNING, ERROR, LOG, FATAL, and 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 NOTICE. Note that LOG has a different rank here than in client_min_messages. Only superusers can increase this option.
Controls the amount of detail written in the server log for each message that is logged. Valid values are TERSE, DEFAULT, and VERBOSE, each adding more fields to displayed messages.
Controls whether or not the SQL statement that causes an error condition will also be recorded in the server log. All SQL statements that cause an error of the specified level, or a higher level, are logged. The default is PANIC (effectively turning this feature off for normal use). Valid values are DEBUG5, DEBUG4, DEBUG3, DEBUG2, DEBUG1, INFO, NOTICE, WARNING, ERROR, FATAL, and PANIC. For example, if you set this to ERROR then all SQL statements causing errors, fatal errors, or panics will be logged. Enabling this option can be helpful in tracking down the source of any errors that appear in the server log. Only superusers can increase this option.
Sets a minimum statement execution time (in milliseconds) for statement to be logged. All SQL statements that run in the time specified or longer will be logged with their duration. Setting this to zero will print all queries and their durations. Minus-one (the default) disables this. For example, if you set it to 250 then all SQL statements that run 250ms or longer will be logged. Enabling this option can be useful in tracking down unoptimized queries in your applications. Only superusers can increase this or set it to minus-one if this option is set by the administrator.
Runs the server silently. If this option is set, the server will automatically run in background and any controlling terminals are disassociated. Thus, no messages are written to standard output or standard error (same effect as postmaster's -S option). Unless syslog logging is enabled, using this option is discouraged since it makes it impossible to see error messages.
Here is a list of the various message severity levels used in these settings:
Provides information for use by developers.
Provides information implicitly requested by the user, e.g., during VACUUM VERBOSE.
Provides information that may be helpful to users, e.g., truncation of long identifiers and the creation of indexes as part of primary keys.
Provides warnings to the user, e.g., COMMIT outside a transaction block.
Reports an error that caused the current transaction to abort.
Reports information of interest to administrators, e.g., checkpoint activity.
Reports an error that caused the current session to abort.
Reports an error that caused all sessions to abort.
These options enable various debugging output to be sent to the client or server log. For each executed query, they print the resulting parse tree, the query rewriter output, or the execution plan. debug_pretty_print indents these displays to produce a more readable but much longer output format. client_min_messages or log_min_messages must be DEBUG1 or lower to send output to the client or server logs. These options are off by default.
This outputs a line to the server logs detailing each successful connection. This is off by default, although it is probably very useful. This option can only be set at server start or in the postgresql.conf configuration file.
Causes the duration of every completed statement to be logged. To use this option, enable log_statement and log_pid so you can link the statement to the duration using the process ID. The default is off. Only superusers can turn off this option if it is enabled by the administrator.
Prefixes each message in the server log file with the process ID of the server process. This is useful to sort out which messages pertain to which connection. The default is off. This parameter does not affect messages logged via syslog, which always contain the process ID.
Causes each SQL statement to be logged. The default is off. Only superusers can turn off this option if it is enabled by the administrator.
Prefixes each server log message with a time stamp. The default is off.
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.
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.
For each query, write performance statistics of the respective module to the server log. This is a crude profiling instrument. All of these options are disabled by default. Only superusers can turn off any of these options if they have been enabled by the administrator.
Controls whether the server should start the statistics-collection subprocess. This is on by default, but may be turned off if you know you have no interest in collecting statistics. This option can only be set at server start.
Enables the collection of statistics on the currently executing command of each session, along with the time at which that command began execution. This option is off by default. Note that even when enabled, this information is not visible to all users, only to superusers and the user owning the session being reported on; so it should not represent a security risk. This data can be accessed via the pg_stat_activity system view; refer to Chapter 23 for more information.
These enable the collection of block-level and row-level statistics on database activity, respectively. These options are off by default. This data can be accessed via the pg_stat and pg_statio family of system views; refer to Chapter 23 for more information.
If on, collected statistics are zeroed out whenever the server is restarted. If off, statistics are accumulated across server restarts. The default is on. This option can only be set at server start.
This variable specifies the order in which schemas are searched when an object (table, data type, function, etc.) is referenced by a simple name with no schema component. When there are objects of identical names in different schemas, the one found first in the search path is used. An object that is not in any of the schemas in the search path can only be referenced by specifying its containing schema with a qualified (dotted) name.
The value for search_path has to be a comma-separated
list of schema names. If one of the list items is
the special value $user, then the schema
having the name returned by SESSION_USER
is substituted, if there
is such a schema. (If not, $user is ignored.)
The system catalog schema, 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 pg_catalog is not in the path then it will be searched before searching any of the path items. It should also be noted that the temporary-table schema, pg_temp_nnn, is implicitly searched before any of these.
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.
The default value for this parameter is '$user, public' (where the second part will be ignored if there is no schema named public). This supports shared use of a database (where no users have private schemas, and all share use of 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.
The current effective value of the search path can be examined
via the SQL function
current_schemas()
. This is not quite the same as
examining the value of search_path, since
current_schemas()
shows how the requests
appearing in search_path were resolved.
For more information on schema handling, see Section 5.8.
This parameter is normally true. When set false, it disables validation of the function body string in CREATE FUNCTION. Disabling validation is occasionally useful to avoid problems such as forward references when restoring function definitions from a dump.
Each SQL transaction has an isolation level, which can be either "read committed" or "serializable". This parameter controls the default isolation level of each new transaction. The default is "read committed".
Consult Chapter 12 and SET TRANSACTION for more information.
A read-only SQL transaction cannot alter non-temporary tables. This parameter controls the default read-only status of each new transaction. The default is false (read/write).
Consult SET TRANSACTION for more information.
Aborts any statement that takes over the specified number of milliseconds. A value of zero turns off the timer, which is the default value.
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 (ISO, Postgres, SQL, or German) and the date field order specification (DMY, MDY, or YMD). These can be set separately or together. The keywords Euro and European are synonyms for DMY; the keywords US, NonEuro, and NonEuropean are synonyms for MDY. See Section 8.5 for more information. The default is ISO, MDY.
Sets the time zone for displaying and interpreting time stamps. The default is to use whatever the system environment specifies as the time zone. See Section 8.5 for more information.
If set to true, ACST, CST, EST, and SAT are interpreted as Australian time zones rather than as North/South American time zones and Saturday. The default is false.
This parameter adjusts the number of digits displayed for floating-point values, including float4, float8, and geometric data types. The parameter value is added to the standard number of digits (FLT_DIG or DBL_DIG as appropriate). The value can be set as high as 2, to include partially-significant digits; this is especially useful for dumping float data that needs to be restored exactly. Or it can be set negative to suppress unwanted digits.
Sets the client-side encoding (character set). The default is to use the database encoding.
Sets the language in which messages are displayed. Acceptable values are system-dependent; see Section 20.1 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.
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.
Sets the locale to use for formatting monetary amounts, for
example with the to_char
family of
functions. Acceptable values are system-dependent; see Section 20.1 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.
Sets the locale to use for formatting numbers, for example
with the to_char()
family of
functions. Acceptable values are system-dependent; see Section 20.1 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.
Sets the locale to use for formatting date and time values. (Currently, this setting does nothing, but it may in the future.) Acceptable values are system-dependent; see Section 20.1 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.
Determines whether EXPLAIN VERBOSE uses the indented or non-indented format for displaying detailed query-tree dumps. The default is on.
If a dynamically loadable module needs to be opened and the specified name does not have a directory component (i.e. the name does not contain a slash), the system will search this path for the specified file. (The name that is used is the name specified in the CREATE FUNCTION or LOAD command.)
The value for dynamic_library_path has to be a colon-separated list of absolute directory names. If a directory name starts with the special value $libdir, the compiled-in PostgreSQL package library directory is substituted. This where the modules provided by the PostgreSQL distribution are installed. (Use pg_config --pkglibdir to print the name of this directory.) For example:
dynamic_library_path = '/usr/local/lib/postgresql:/home/my_project/lib:$libdir'
The default value for this parameter is '$libdir'. If the value is set to an empty string, the automatic path search is turned off.
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 postgresql.conf configuration file.
Sets the maximum expression nesting depth of the parser. The default value of 10000 is high enough for any normal query, but you can raise it if needed. (But if you raise it too high, you run the risk of server crashes due to stack overflow.)
This is the amount of time, in milliseconds, to wait on a lock before checking to see if there is a deadlock condition. The check for deadlock is relatively slow, so the server doesn't run it every time it waits for a lock. We (optimistically?) assume that deadlocks are not common in production applications and just wait on the lock for a while before starting the check for a deadlock. Increasing this value reduces the amount of time wasted in needless deadlock checks, but slows down reporting of real deadlock errors. The default is 1000 (i.e., one second), which is probably about the smallest value you would want in practice. On a heavily loaded server you might want to raise it. Ideally the setting should exceed your typical transaction time, so as to improve the odds that a lock will be released before the waiter decides to check for deadlock.
The shared lock table is sized on the assumption that at most max_locks_per_transaction * max_connections distinct objects will need to be locked at any one time. The default, 64, has historically proven sufficient, but you might need to raise this value if you have clients that touch many different tables in a single transaction. This option can only be set at server start.
When true, tables that are referenced by a query will be automatically added to the FROM clause if not already present. The default is true for compatibility with previous releases of PostgreSQL. However, this behavior is not SQL-standard, and many people dislike it because it can mask mistakes. Set to false for the SQL-standard behavior of rejecting references to tables that are not listed in FROM.
The regular expression "flavor" can be set to advanced, extended, or basic. The default is advanced. The extended setting may be useful for exact backwards compatibility with pre-7.4 releases of PostgreSQL.
This controls the inheritance semantics, in particular whether subtables are included by various commands by default. They were not included in versions prior to 7.1. If you need the old behavior you can set this variable to off, but in the long run you are encouraged to change your applications to use the ONLY key word to exclude subtables. See Section 5.5 for more information about inheritance.
When turned on, expressions of the form expr = NULL (or NULL = expr) are treated as expr IS NULL, that is, they return true if expr evaluates to the null value, and false otherwise. The correct behavior of expr = NULL is to always return null (unknown). Therefore this option defaults to off.
However, filtered forms in Microsoft Access generate queries that appear to use expr = NULL 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 expr = NULL always return the null value (using the correct interpretation) they are not very useful and do not appear often in normal applications, so this option does little harm in practice. But new users are frequently confused about the semantics of expressions involving null values, so this option is not on by default.
Note that this option only affects the literal = operator, not other comparison operators or other expressions that are computationally equivalent to some expression involving the equals operator (such as IN). Thus, this option is not a general fix for bad programming.
Refer to Section 9.2 for related information.
The following options are intended for work on the PostgreSQL source, and in some cases to assist with recovery of severely damaged databases. There should be no reason to use them in a production database setup. As such, they have been excluded from the sample postgresql.conf file. Note that many of these options require special source compilation flags to work at all.
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 PostgreSQL is built (accomplished by the configure option --enable-cassert). Note that DEBUG_ASSERTIONS defaults to on if PostgreSQL has been built with assertions enabled.
If nonzero, a delay of this many seconds occurs just after a new server process is forked, before it conducts the authentication process. This is intended to give an opportunity to attach to the server process with a debugger to trace down misbehavior in authentication.
Generates a great amount of debugging output for the LISTEN and NOTIFY commands. client_min_messages or log_min_messages must be DEBUG1 or lower to send this output to the client or server log, respectively.
Various other code tracing and debugging options.
If nonzero, turn on WAL-related debugging output.
Detection of a damaged page header normally causes PostgreSQL to report an error, aborting the current transaction. Setting zero_damaged_pages to true causes the system to instead report a warning, zero out the damaged page, and continue processing. This behavior will destroy data, namely all the rows on the damaged page. But it allows you to get past the error and retrieve rows from any undamaged pages that may be present in the table. So it is useful for recovering data if corruption has occurred due to hardware or software error. You should generally not set this true until you have given up hope of recovering data from the damaged page(s) of a table. The default setting is off, and it can only be changed by a superuser.
For convenience there are also single letter command-line option switches available for some parameters. They are described in Table 16-1.
Table 16-1. Short option key
Short option | Equivalent |
---|---|
-B x | shared_buffers = x |
-d x | log_min_messages = DEBUGx |
-F | fsync = off |
-h x | virtual_host = x |
-i | tcpip_socket = on |
-k x | unix_socket_directory = x |
-l | ssl = on |
-N x | max_connections = x |
-p x | port = x |
-fi, -fh, -fm, -fn, -fs, -ft[a] | enable_indexscan=off, enable_hashjoin=off, enable_mergejoin=off, enable_nestloop=off, enable_seqscan=off, enable_tidscan=off |
-s[a] | log_statement_stats = on |
-S x[a] | sort_mem = x |
-tpa, -tpl, -te[a] | log_parser_stats=on, log_planner_stats=on, log_executor_stats=on |
Notes: a. For historical reasons, these options must be passed to the individual server process via the -o postmaster option, for example, $ postmaster -o '-S 1024 -s'
or via PGOPTIONS from the client side, as
explained above.
|