From 9813fc1bae21e4027a72d88fcb0528922150d457 Mon Sep 17 00:00:00 2001 From: Neil Conway Date: Mon, 12 Sep 2005 22:11:38 +0000 Subject: [PATCH] Make the documentation of GUC variables a separate chapter, rather than a section of the "Server Run-time Environment" chapter. Also, move the SGML for the new chapter to a separate file and fix the resulting fallout. --- doc/src/sgml/config.sgml | 4238 ++++++++++++++++++++++++++++++++++++ doc/src/sgml/filelist.sgml | 3 +- doc/src/sgml/postgres.sgml | 3 +- doc/src/sgml/runtime.sgml | 4220 +---------------------------------- 4 files changed, 4243 insertions(+), 4221 deletions(-) create mode 100644 doc/src/sgml/config.sgml diff --git a/doc/src/sgml/config.sgml b/doc/src/sgml/config.sgml new file mode 100644 index 0000000000..de5e71eb42 --- /dev/null +++ b/doc/src/sgml/config.sgml @@ -0,0 +1,4238 @@ + + + Run-time Configuration + + + configuration + of the server + + + + There are many configuration parameters that affect the behavior of + the database system. In the first section of this chapter, we + describe how to set configuration chapters. The subsequent sections + discuss each parameter in detail. + + + + Setting Parameters + + + All parameter names are case-insensitive. Every parameter takes a + value of one of four types: boolean, integer, floating point, + or string. Boolean values may be written as ON, + OFF, TRUE, + FALSE, YES, + NO, 1, 0 + (all case-insensitive) or any unambiguous prefix of these. + + + + One way to set these parameters is to edit the file + postgresql.confpostgresql.conf, + which is normally kept in the data directory. (initdb + installs a default copy there.) An example of what this file might look + like is: + +# This is a comment +log_connections = yes +log_destination = 'syslog' +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 must be single-quoted. + + + + + SIGHUP + + 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. 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. + + + + 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 log_destination='syslog' + + Command-line options override any conflicting settings in + postgresql.conf. Note that this means you won't + be able to change the value on-the-fly by editing + postgresql.conf, so while the command-line + method may be convenient, it can cost you flexibility later. + + + + Occasionally it is 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 or that must be + specified in postgresql.conf. + + + + 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 + and , + 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 + command, for example: + +SET ENABLE_SEQSCAN TO OFF; + + If SET is allowed, it overrides all other sources of + values for the parameter. Some parameters cannot be changed via + SET: for example, if they control behavior that + cannot reasonably be changed without restarting + PostgreSQL. Also, some parameters can + be modified via SET or ALTER by superusers, + but not by ordinary users. + + + + The + command allows inspection of the current values of all parameters. + + + + The virtual table pg_settings + (described in ) 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. + + + + + File Locations + + + In addition to the postgresql.conf file + already mentioned, PostgreSQL uses + two other manually-edited configuration files, which control + client authentication (their use is discussed in ). By default, all three + configuration files are stored in the database cluster's data + directory. The options described in this section allow the + configuration files to be placed elsewhere. (Doing so can ease + administration. In particular it is often easier to ensure that + the configuration files are properly backed-up when they are + kept separate.) + + + + + data_directory (string) + + data_directory configuration parameter + + + + Specifies the directory to use for data storage. + This option can only be set at server start. + + + + + + config_file (string) + + config_file configuration parameter + + + + Specifies the main server configuration file + (customarily called postgresql.conf). + This option can only be set on the postmaster command line. + + + + + + hba_file (string) + + hba_file configuration parameter + + + + Specifies the configuration file for host-based authentication + (customarily called pg_hba.conf). + This option can only be set at server start. + + + + + + ident_file (string) + + ident_file configuration parameter + + + + Specifies the configuration file for + ident authentication + (customarily called pg_ident.conf). + This option can only be set at server start. + + + + + + external_pid_file (string) + + external_pid_file configuration parameter + + + + Specifies the name of an additional process-id (PID) file that the + postmaster should create for use by server + administration programs. + This option can only be set at server start. + + + + + + + In a default installation, none of the above options are set explicitly. + Instead, the + data directory is specified by the command-line + option or the PGDATA environment variable, and the + configuration files are all found within the data directory. + + + + If you wish to keep the configuration files elsewhere than the + data directory, the postmaster's + command-line option or PGDATA environment variable + must point to the directory containing the configuration files, + and the data_directory option must be set in + postgresql.conf (or on the command line) to show + where the data directory is actually located. Notice that + data_directory overrides and + PGDATA for the location + of the data directory, but not for the location of the configuration + files. + + + + If you wish, you can specify the configuration file names and locations + individually using the options config_file, + hba_file and/or ident_file. + config_file can only be specified on the + postmaster command line, but the others can be + set within the main configuration file. If all three options plus + data_directory are explicitly set, then it is not necessary + to specify or PGDATA. + + + + When setting any of these options, a relative path will be interpreted + with respect to the directory in which the postmaster + is started. + + + + + Connections and Authentication + + + Connection Settings + + + + + listen_addresses (string) + + listen_addresses configuration parameter + + + + Specifies the TCP/IP address(es) on which the server is + to listen for connections from client applications. + The value takes the form of a comma-separated list of host names + and/or numeric IP addresses. The special entry * + corresponds to all available IP interfaces. + If the list is empty, the server does not listen on any IP interface + at all, in which case only Unix-domain sockets can be used to connect + to it. + The default value is localhost, + which allows only local loopback connections to be made. + This parameter can only be set at server start. + + + + + + port (integer) + + port configuration parameter + + + + The TCP port the server listens on; 5432 by default. Note that the + same port number is used for all IP addresses the server listens on. + This parameter can only be set at server start. + + + + + + max_connections (integer) + + max_connections configuration parameter + + + + 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 for information on how to + adjust those parameters, if necessary. + + + + + + superuser_reserved_connections + (integer) + + superuser_reserved_connections configuration parameter + + + + Determines the number of connection slots that + are reserved for connections by PostgreSQL + superusers. At most + 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. + + + + + + unix_socket_directory (string) + + unix_socket_directory configuration parameter + + + + 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. + This parameter can only be set at server start. + + + + + + unix_socket_group (string) + + unix_socket_group configuration parameter + + + + Sets the owning group of the Unix-domain socket. (The owning + user of the socket is always the user that starts the + server.) In combination with the option + unix_socket_permissions this can be used as + an additional access control mechanism for Unix-domain connections. + By default this is the empty string, which uses the default + group for the current user. This option can only be set at + server start. + + + + + + unix_socket_permissions (integer) + + unix_socket_permissions configuration parameter + + + + 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 are + 0770 (only user and group, see also + unix_socket_group) and 0700 + (only user). (Note that for a Unix-domain socket, only write + permission matters and so there is no point in setting or revoking + read or execute permissions.) + + + + This access control mechanism is independent of the one + described in . + + + + This option can only be set at server start. + + + + + + bonjour_name (string) + + bonjour_name configuration parameter + + + + Specifies the Bonjour broadcast + name. By default, the computer name is used, specified as an + empty string ''. This option is ignored if the server was not + compiled with Bonjour support. This + option can only be set at server start. + + + + + + tcp_keepalives_idle (integer) + + tcp_keepalives_idle configuration parameter + + + + On systems that support the TCP_KEEPIDLE socket option, specifies the + number of seconds between sending keepalives on an otherwise idle + connection. A value of 0 uses the system default. If TCP_KEEPIDLE is + not supported, this parameter must be 0. This option is ignored for + connections made via a Unix-domain socket. + + + + + + tcp_keepalives_interval (integer) + + tcp_keepalives_interval configuration parameter + + + + On systems that support the TCP_KEEPINTVL socket option, specifies how + long, in seconds, to wait for a response to a keepalive before + retransmitting. A value of 0 uses the system default. If TCP_KEEPINTVL + is not supported, this parameter must be 0. This option is ignored + for connections made via a Unix-domain socket. + + + + + + tcp_keepalives_count (integer) + + tcp_keepalives_count configuration parameter + + + + On systems that support the TCP_KEEPCNT socket option, specifies how + many keepalives may be lost before the connection is considered dead. + A value of 0 uses the system default. If TCP_KEEPINTVL is not + supported, this parameter must be 0. + + + + + + + + Security and Authentication + + + + authentication_timeout (integer) + timeoutclient authentication + client authenticationtimeout during + + authentication_timeout configuration parameter + + + + + 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. + + + + + + ssl (boolean) + + ssl configuration parameter + + + + Enables SSL connections. Please read + before using this. The default + is off. This parameter can only be set at server + start. + + + + + + password_encryption (boolean) + + password_encryption configuration parameter + + + + When a password is specified in or + + without writing either ENCRYPTED or + UNENCRYPTED, this option determines whether the + password is to be encrypted. The default is on + (encrypt the password). + + + + + + krb_server_keyfile (string) + + krb_server_keyfile configuration parameter + + + + Sets the location of the Kerberos server key file. See + for details. This parameter + can only be set at server start. + + + + + + krb_srvname (string) + + krb_srvname configuration parameter + + + + Sets the Kerberos service name. See + for details. This parameter can only be set at server start. + + + + + + krb_server_hostname (string) + + krb_server_hostname configuration parameter + + + + Sets the hostname part of the service principal. + This, combined with krb_srvname, is used to generate + the complete service principal, i.e. + krb_server_hostname/krb_server_hostname@REALM. + + + If not set, the default is to allow any service principal matching an entry + in the keytab. See for details. + This parameter can only be set at server start. + + + + + + krb_caseins_users (boolean) + + krb_caseins_users configuration parameter + + + + Sets if Kerberos usernames should be treated case-insensitively. + The default is off (case sensitive). This parameter + can only be set at server start. + + + + + + db_user_namespace (boolean) + + db_user_namespace configuration parameter + + + + This enables 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 are appended to the user + name and that database-specific user name is looked up by the + server. Note that when you create users with names containing + @ 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. + + + + + This feature is intended as a temporary measure until a + complete solution is found. At that time, this option will + be removed. + + + + + + + + + + + Resource Consumption + + + Memory + + + + shared_buffers (integer) + + shared_buffers configuration parameter + + + + 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 ; + 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 for information on how to + adjust those parameters, if necessary. + + + + + + temp_buffers (integer) + + temp_buffers configuration parameter + + + + Sets the maximum number of temporary buffers used by each database + session. These are session-local buffers used only for access + to temporary tables. The default is 1000. The setting can + be changed within individual sessions, but only up until the + first use of temporary tables within a session; subsequent + attempts to change the value will have no effect on that session. + + + + A session will allocate temporary buffers as needed up to the limit + given by temp_buffers. The cost of setting a large + value in sessions that do not actually need a lot of temporary + buffers is only a buffer descriptor, or about 64 bytes, per + increment in temp_buffers. However if a buffer is + actually used an additional 8192 bytes will be consumed for it + (or in general, BLCKSZ bytes). + + + + + + max_prepared_transactions (integer) + + max_prepared_transactions configuration parameter + + + + Sets the maximum number of transactions that can be in the + prepared state simultaneously (see ). + Setting this parameter to zero disables the prepared-transaction + feature. + The default is 5. + This option can only be set at server start. + + + + If you are not using prepared transactions, this parameter may as + well be set to zero. If you are using them, you will probably + want max_prepared_transactions to be at least + as large as , to avoid unwanted + failures at the prepare step. + + + + Increasing this parameter may cause PostgreSQL + to request more System V shared + memory than your operating system's default configuration + allows. See for information on how to + adjust those parameters, if necessary. + + + + + + work_mem (integer) + + work_mem configuration parameter + + + + 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 such operations + concurrently. So the total memory used could be many + times the value of work_mem; it is necessary to + keep this fact in mind when choosing the value. Sort operations are + used for ORDER BY, DISTINCT, and + merge joins. + Hash tables are used in hash joins, hash-based aggregation, and + hash-based processing of IN subqueries. + + + + + + maintenance_work_mem (integer) + + maintenance_work_mem configuration parameter + + + + Specifies the maximum amount of memory to be used in maintenance + operations, such as VACUUM, CREATE + INDEX, and ALTER TABLE ADD FOREIGN KEY. + The value is specified in kilobytes, and defaults to 16384 kilobytes + (16 MB). Since only one of these operations can be executed at + a time by a database session, and an installation normally doesn't + have very many of them happening concurrently, it's safe to set this + value significantly larger than work_mem. Larger + settings may improve performance for vacuuming and for restoring + database dumps. + + + + + + max_stack_depth (integer) + + max_stack_depth configuration parameter + + + + Specifies the maximum safe depth of the server's execution stack. + The ideal setting for this parameter is the actual stack size limit + enforced by the kernel (as set by ulimit -s or local + equivalent), less a safety margin of a megabyte or so. The safety + margin is needed because the stack depth is not checked in every + routine in the server, but only in key potentially-recursive routines + such as expression evaluation. Setting the parameter higher than + the actual kernel limit will mean that a runaway recursive function + can crash an individual backend process. The default setting is + 2048 KB (two megabytes), which is conservatively small and unlikely + to risk crashes. However, it may be too small to allow execution + of complex functions. + + + + + + + + Free Space Map + + + free space map + + + + These parameters control the size of the shared free space + map, which tracks the locations of unused space in the database. + An undersized free space map may cause the database to consume + increasing amounts of disk space over time, because free space that + is not in the map cannot be re-used; instead PostgreSQL + will request more disk space from the operating system when it needs + to store new data. + The last few lines displayed by a database-wide VACUUM VERBOSE + command can help in determining if the current settings are adequate. + A NOTICE message is also printed during such an operation + if the current settings are too low. + + + + Increasing these parameters may cause PostgreSQL + to request more System V shared + memory than your operating system's default configuration + allows. See for information on how to + adjust those parameters, if necessary. + + + + + max_fsm_pages (integer) + + max_fsm_pages configuration parameter + + + + 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. + + + + + + max_fsm_relations (integer) + + max_fsm_relations configuration parameter + + + + Sets the maximum number of relations (tables and indexes) for which + free space will be tracked in the shared free-space map. Roughly + seventy bytes of shared memory are consumed for each slot. + The default is 1000. + This option can only be set at server start. + + + + + + + + Kernel Resource Usage + + + + max_files_per_process (integer) + + max_files_per_process configuration parameter + + + + 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. + + + + + + preload_libraries (string) + + preload_libraries configuration parameter + + + + 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 a specified library or initialization function is 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 slightly, even if that process never + uses the library. So this option is recommended only for + libraries that will be used in most sessions. + + + + + + + + + + Cost-Based Vacuum Delay + + + + During the execution of and commands, the system maintains an + internal counter that keeps track of the estimated cost of the + various I/O operations that are performed. When the accumulated + cost reaches a limit (specified by + vacuum_cost_limit), the process performing + the operation will sleep for a while (specified by + vacuum_cost_delay). Then it will reset the + counter and continue execution. + + + + The intent of this feature is to allow administrators to reduce + the I/O impact of these commands on concurrent database + activity. There are many situations in which it is not very + important that maintenance commands like + VACUUM and ANALYZE finish + quickly; however, it is usually very important that these + commands do not significantly interfere with the ability of the + system to perform other database operations. Cost-based vacuum + delay provides a way for administrators to achieve this. + + + + This feature is disabled by default. To enable it, set the + vacuum_cost_delay variable to a nonzero + value. + + + + + vacuum_cost_delay (integer) + + vacuum_cost_delay configuration parameter + + + + The length of time, in milliseconds, that the process will sleep + when the cost limit has been exceeded. + The default value is 0, which disables the cost-based vacuum + delay feature. Positive values enable cost-based vacuuming. + Note that on many systems, the effective resolution + of sleep delays is 10 milliseconds; setting + vacuum_cost_delay to a value that is + not a multiple of 10 may have the same results as setting it + to the next higher multiple of 10. + + + + + + vacuum_cost_page_hit (integer) + + vacuum_cost_page_hit configuration parameter + + + + The estimated cost for vacuuming a buffer found in the shared buffer + cache. It represents the cost to lock the buffer pool, lookup + the shared hash table and scan the content of the page. The + default value is 1. + + + + + + vacuum_cost_page_miss (integer) + + vacuum_cost_page_miss configuration parameter + + + + The estimated cost for vacuuming a buffer that has to be read from + disk. This represents the effort to lock the buffer pool, + lookup the shared hash table, read the desired block in from + the disk and scan its content. The default value is 10. + + + + + + vacuum_cost_page_dirty (integer) + + vacuum_cost_page_dirty configuration parameter + + + + The estimated cost charged when vacuum modifies a block that was + previously clean. It represents the extra I/O required to + flush the dirty block out to disk again. The default value is + 20. + + + + + + vacuum_cost_limit (integer) + + vacuum_cost_limit configuration parameter + + + + The accumulated cost that will cause the vacuuming process to sleep. + The default value is 200. + + + + + + + + There are certain operations that hold critical locks and should + therefore complete as quickly as possible. Cost-based vacuum + delays do not occur during such operations. Therefore it is + possible that the cost accumulates far higher than the specified + limit. To avoid uselessly long delays in such cases, the actual + delay is calculated as vacuum_cost_delay * + accumulated_balance / + vacuum_cost_limit with a maximum of + vacuum_cost_delay * 4. + + + + + + Background Writer + + + Beginning in PostgreSQL 8.0, there is a separate server + process called the background writer, whose sole function + is to issue writes of dirty shared buffers. The intent is + that server processes handling user queries should seldom or never have + to wait for a write to occur, because the background writer will do it. + This arrangement also reduces the performance penalty associated with + checkpoints. The background writer will continuously trickle out dirty + pages to disk, so that only a few pages will need to be forced out when + checkpoint time arrives, instead of the storm of dirty-buffer writes that + formerly occurred at each checkpoint. However there is a net overall + increase in I/O load, because where a repeatedly-dirtied page might + before have been written only once per checkpoint interval, the + background writer might write it several times in the same interval. + In most situations a continuous low load is preferable to periodic + spikes, but the parameters discussed in this subsection can be used to tune + the behavior for local needs. + + + + + bgwriter_delay (integer) + + bgwriter_delay configuration parameter + + + + Specifies the delay between activity rounds for the + background writer. In each round the writer issues writes + for some number of dirty buffers (controllable by the + following parameters). It then sleeps for bgwriter_delay + milliseconds, and repeats. The default value is 200. Note + that on many systems, the effective resolution of sleep + delays is 10 milliseconds; setting bgwriter_delay + to a value that is not a multiple of 10 may have the same + results as setting it to the next higher multiple of 10. + This option can only be set at server start or in the + postgresql.conf file. + + + + + + bgwriter_lru_percent (floating point) + + bgwriter_lru_percent configuration parameter + + + + To reduce the probability that server processes will need to issue + their own writes, the background writer tries to write buffers that + are likely to be recycled soon. In each round, it examines up to + bgwriter_lru_percent of the buffers that are nearest to + being recycled, and writes any that are dirty. + The default value is 1.0 (this is a percentage of the total number + of shared buffers). + This option can only be set at server start or in the + postgresql.conf file. + + + + + + bgwriter_lru_maxpages (integer) + + bgwriter_lru_maxpages configuration parameter + + + + In each round, no more than this many buffers will be written + as a result of scanning soon-to-be-recycled buffers. + The default value is 5. + This option can only be set at server start or in the + postgresql.conf file. + + + + + + bgwriter_all_percent (floating point) + + bgwriter_all_percent configuration parameter + + + + To reduce the amount of work that will be needed at checkpoint time, + the background writer also does a circular scan through the entire + buffer pool, writing buffers that are found to be dirty. + In each round, it examines up to + bgwriter_all_percent of the buffers for this purpose. + The default value is 0.333 (this is a percentage of the total number + of shared buffers). With the default bgwriter_delay + setting, this will allow the entire shared buffer pool to be scanned + about once per minute. + This option can only be set at server start or in the + postgresql.conf file. + + + + + + bgwriter_all_maxpages (integer) + + bgwriter_all_maxpages configuration parameter + + + + In each round, no more than this many buffers will be written + as a result of the scan of the entire buffer pool. (If this + limit is reached, the scan stops, and resumes at the next buffer + during the next round.) + The default value is 5. + This option can only be set at server start or in the + postgresql.conf file. + + + + + + + Smaller values of bgwriter_all_percent and + bgwriter_all_maxpages reduce the extra I/O load + caused by the background writer, but leave more work to be done + at checkpoint time. To reduce load spikes at checkpoints, + increase these two values. + Similarly, smaller values of bgwriter_lru_percent and + bgwriter_lru_maxpages reduce the extra I/O load + caused by the background writer, but make it more likely that server + processes will have to issue writes for themselves, delaying interactive + queries. + To disable background writing entirely, + set both maxpages values and/or both + percent values to zero. + + + + + + Write Ahead Log + + + See also for details on WAL + tuning. + + + + Settings + + + + + fsync configuration parameter + + fsync (boolean) + + + 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. + + + + 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. + (Crashes of the database server itself are not + a risk factor here. Only an operating-system-level crash + creates a risk of corruption.) + + + + 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. If this option + is off, consider also turning off + guc-full-page-writes. + + + + + + wal_sync_method (string) + + wal_sync_method configuration parameter + + + + Method used for forcing WAL updates out to disk. Possible + values are: + + + + + open_datasync (write WAL files with open() option O_DSYNC) + + + + + fdatasync (call fdatasync() at each commit), + + + + + fsync (call fsync() at each commit) + + + + + fsync_writethrough (force write-through of any disk write cache) + + + + + open_sync (write WAL files with open() option O_SYNC) + + + + + Not all of these choices are available on all platforms. + The top-most supported option is used as the default. + If fsync is off then this setting is irrelevant. + This option can only be set at server start or in the + postgresql.conf file. + + + + + + + full_page_writes configuration parameter + + full_page_writes (boolean) + + + A page write in process during an operating system crash might + be only partially written to disk, leading to an on-disk page + that contains a mix of old and new data. During recovery, the + row changes stored in WAL are not enough to completely restore + the page. + + + + When this option is on, the PostgreSQL server + writes full pages to WAL when they are first modified after a + checkpoint so full recovery is possible. Turning this option off + might lead to a corrupt system after an operating system crash + or power failure because uncorrected partial pages might contain + inconsistent or corrupt data. The risks are less but similar to + fsync. + + + + This option can only be set at server start or in the + postgresql.conf file. The default is + on. + + + + + + wal_buffers (integer) + + wal_buffers configuration parameter + + + + Number of disk-page buffers allocated in shared memory for WAL data. + The default is 8. The setting need only be large enough to hold + the amount of WAL data generated by one typical transaction, since + the data is flushed to disk at every transaction commit. + 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 for information on how to + adjust those parameters, if necessary. + + + + + + commit_delay (integer) + + commit_delay configuration parameter + + + + Time delay between writing a commit record to the WAL buffer + and flushing the buffer out to disk, in microseconds. A + nonzero delay can allow multiple transactions to be committed + with only one fsync() system call, if + system load is high enough that additional transactions become + ready to commit within the given interval. But the delay is + just wasted if no other transactions become ready to + commit. Therefore, the delay is only performed if at least + commit_siblings other transactions are + active at the instant that a server process has written its + commit record. The default is zero (no delay). + + + + + + commit_siblings (integer) + + commit_siblings configuration parameter + + + + 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. + + + + + + + + Checkpoints + + + + checkpoint_segments (integer) + + checkpoint_segments configuration parameter + + + + 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. + + + + + + checkpoint_timeout (integer) + + checkpoint_timeout configuration parameter + + + + 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. + + + + + + checkpoint_warning (integer) + + checkpoint_warning configuration parameter + + + + Write a message to the server log if checkpoints caused by + the filling of checkpoint segment files happen closer together + than this many seconds. The default is 30 seconds. + Zero turns off the warning. + + + + + + + + Archiving + + + + archive_command (string) + + archive_command configuration parameter + + + + The shell command to execute to archive a completed segment of + the WAL file series. If this is an empty string (the default), + WAL archiving is disabled. Any %p in the string is + replaced by the absolute path of the file to archive, and any + %f is replaced by the file name only. Use + %% to embed an actual % character in the + command. For more information see . This option can only be set at + server start or in the postgresql.conf + file. + + + It is important for the command to return a zero exit status if + and only if it succeeds. Examples: + +archive_command = 'cp "%p" /mnt/server/archivedir/"%f"' +archive_command = 'copy "%p" /mnt/server/archivedir/"%f"' # Windows + + + + + + + + + + + Query Planning + + + Planner Method Configuration + + + These configuration parameters provide a crude method of + influencing the query plans chosen by the query optimizer. If + the default plan chosen by the optimizer for a particular query + is not optimal, a temporary solution may be found by using one + of these configuration parameters to force the optimizer to + choose a different plan. Turning one of these settings off + permanently is seldom a good idea, however. + Better ways to improve the quality of the + plans chosen by the optimizer include adjusting the , running more + frequently, increasing the value of the configuration parameter, + and increasing the amount of statistics collected for + specific columns using ALTER TABLE SET + STATISTICS. + + + + + enable_bitmapscan (boolean) + + bitmap scan + + + enable_bitmapscan configuration parameter + + + + Enables or disables the query planner's use of bitmap-scan plan + types. The default is on. + + + + + + enable_hashagg (boolean) + + enable_hashagg configuration parameter + + + + Enables or disables the query planner's use of hashed + aggregation plan types. The default is on. + + + + + + enable_hashjoin (boolean) + + enable_hashjoin configuration parameter + + + + Enables or disables the query planner's use of hash-join plan + types. The default is on. + + + + + + enable_indexscan (boolean) + + index scan + + + enable_indexscan configuration parameter + + + + Enables or disables the query planner's use of index-scan plan + types. The default is on. + + + + + + enable_mergejoin (boolean) + + enable_mergejoin configuration parameter + + + + Enables or disables the query planner's use of merge-join plan + types. The default is on. + + + + + + enable_nestloop (boolean) + + enable_nestloop configuration parameter + + + + 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. + + + + + + enable_seqscan (boolean) + + sequential scan + + + enable_seqscan configuration parameter + + + + 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. + + + + + + enable_sort (boolean) + + enable_sort configuration parameter + + + + 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. + + + + + + enable_tidscan (boolean) + + enable_tidscan configuration parameter + + + + Enables or disables the query planner's use of TID + scan plan types. The default is on. + + + + + + + + + Planner Cost Constants + + + + + 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. + + + + + + + effective_cache_size (floating point) + + effective_cache_size configuration parameter + + + + Sets the planner's assumption about the effective size of the + disk cache that is available to a single index scan. This is + factored into estimates of the cost of using an index; a higher + value makes it more likely index scans will be used, a lower + value makes it more likely sequential scans will be used. When + setting this parameter you should consider both + PostgreSQL's shared buffers and the + portion of the kernel's disk cache that will be used for + PostgreSQL data files. Also, take into + account the expected number of concurrent queries using different + indexes, since they will have to share the available space. + This parameter has no effect on the size of shared memory + allocated by PostgreSQL, nor does it reserve kernel disk cache; + it is used only for estimation purposes. + The value is measured in disk pages, which are + normally 8192 bytes each. The default is 1000. + + + + + + random_page_cost (floating point) + + random_page_cost configuration parameter + + + + Sets the 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. + + + + + + cpu_tuple_cost (floating point) + + cpu_tuple_cost configuration parameter + + + + Sets the 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. + + + + + + cpu_index_tuple_cost (floating point) + + cpu_index_tuple_cost configuration parameter + + + + Sets the 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. + + + + + + cpu_operator_cost (floating point) + + cpu_operator_cost configuration parameter + + + + 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. + + + + + + + + + Genetic Query Optimizer + + + + + + genetic query optimization + + + GEQO + genetic query optimization + + + geqo configuration parameter + + geqo (boolean) + + + Enables or disables genetic query optimization, which is an + algorithm that attempts to do query planning without + exhaustive searching. This is on by default. The + geqo_threshold variable provides a more + granular way to disable GEQO for certain classes of queries. + + + + + + geqo_threshold (integer) + + geqo_threshold configuration parameter + + + + 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 12. For simpler queries it is usually best + to use the deterministic, exhaustive planner, but for queries with + many tables the deterministic planner takes too long. + + + + + + geqo_effort + (integer) + + geqo_effort configuration parameter + + + + Controls the trade off between planning time and query plan + efficiency in GEQO. This variable must be an integer in the + range from 1 to 10. The default value is 5. Larger values + increase the time spent doing query planning, but also + increase the likelihood that an efficient query plan will be + chosen. + + + + geqo_effort doesn't actually do anything + directly; it is only used to compute the default values for + the other variables that influence GEQO behavior (described + below). If you prefer, you can set the other parameters by + hand instead. + + + + + + geqo_pool_size (integer) + + geqo_pool_size configuration parameter + + + + Controls the pool size used by GEQO. The pool size is the + number of individuals in the genetic population. It must be + at least two, and useful values are typically 100 to 1000. If + it is set to zero (the default setting) then a suitable + default is chosen based on geqo_effort and + the number of tables in the query. + + + + + + geqo_generations (integer) + + geqo_generations configuration parameter + + + + Controls the number of generations used by GEQO. Generations + specifies the number of iterations of the algorithm. It must + be at least one, and useful values are in the same range as + the pool size. If it is set to zero (the default setting) + then a suitable default is chosen based on + geqo_pool_size. + + + + + + geqo_selection_bias (floating point) + + geqo_selection_bias configuration parameter + + + + Controls the selection bias used by GEQO. The selection bias + is the selective pressure within the population. Values can be + from 1.50 to 2.00; the latter is the default. + + + + + + + + Other Planner Options + + + + + default_statistics_target (integer) + + default_statistics_target configuration parameter + + + + 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. For more information + on the use of statistics by the PostgreSQL + query planner, refer to . + + + + + + constraint_exclusion (boolean) + + constraint exclusion + + + constraint_exclusion configuration parameter + + + + Enables or disables the query planner's use of table constraints to + limit table access. The default is off. + + + + When this parameter is on, the planner compares query + conditions with table CHECK constraints, and omits scanning tables + where the conditions contradict the constraints. (Presently + this is done only for child tables of inheritance scans.) For + example: + + +CREATE TABLE parent(key integer, ...); +CREATE TABLE child1000(check (key between 1000 and 1999)) INHERITS(parent); +CREATE TABLE child2000(check (key between 2000 and 2999)) INHERITS(parent); +... +SELECT * FROM parent WHERE key = 2400; + + + With constraint exclusion enabled, this SELECT will not scan + child1000 at all. This can improve performance when + inheritance is used to build partitioned tables. + + + + Currently, constraint_exclusion defaults to + off, because it risks incorrect results if + query plans are cached --- if a table constraint is changed or dropped, + the previously generated plan might now be wrong, and there is no + built-in mechanism to force re-planning. (This deficiency will + probably be addressed in a future + PostgreSQL release.) Another reason + for keeping it off is that the constraint checks are relatively + expensive, and in many circumstances will yield no savings. + It is recommended to turn this on only if you are actually using + partitioned tables designed to take advantage of the feature. + + + + + + from_collapse_limit (integer) + + from_collapse_limit configuration parameter + + + + 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 . + + + + + + join_collapse_limit (integer) + + join_collapse_limit configuration parameter + + + + The planner will rewrite explicit inner JOIN + constructs into lists of FROM items whenever a + list of no more than this many items in total would + result. Prior to PostgreSQL 7.4, joins + specified via the JOIN construct would + never be reordered by the query planner. The query planner has + subsequently been improved so that inner joins written in this + form can be reordered; this configuration parameter controls + the extent to which this reordering is performed. + + + At present, the order of outer joins specified via the + JOIN construct is never adjusted by the query + planner; therefore, join_collapse_limit has no + effect on this behavior. The planner may be improved to + reorder some classes of outer joins in a future release of + PostgreSQL. + + + + + + By default, this variable is set the same as + from_collapse_limit, which is appropriate + for most uses. Setting it to 1 prevents any reordering of + inner JOINs. Thus, the explicit join order + specified in the query will be the actual order in which the + relations are joined. The query planner does not always choose + the optimal join order; advanced users may elect to + temporarily set this variable to 1, and then specify the join + order they desire explicitly. Another consequence of setting + this variable to 1 is that the query planner will behave more + like the PostgreSQL 7.3 query + planner, which some users might find useful for backward + compatibility reasons. + + + + Setting this variable to a value between 1 and + from_collapse_limit might be useful to + trade off planning time against the quality of the chosen plan + (higher values produce better plans). + + + + + + + + + + Error Reporting and Logging + + + server log + + + + Where to log + + + where to log + + + + + + log_destination (string) + + log_destination configuration parameter + + + + PostgreSQL supports several methods + for logging server messages, including + stderr and + syslog. On Windows, + eventlog is also supported. Set this + option to a list of desired log destinations separated by + commas. The default is to log to stderr + only. + This option can only be set at server start or in the + postgresql.conf configuration file. + + + + + + redirect_stderr (boolean) + + redirect_stderr configuration parameter + + + + This option allows messages sent to stderr to be + captured and redirected into log files. + This option, in combination with logging to stderr, + is often more useful than + logging to syslog, since some types of messages + may not appear in syslog output (a common example + is dynamic-linker failure messages). + This option can only be set at server start. + + + + + + log_directory (string) + + log_directory configuration parameter + + + + When redirect_stderr is enabled, this option + determines the directory in which log files will be created. + It may be specified as an absolute path, or relative to the + cluster data directory. + This option can only be set at server start or in the + postgresql.conf configuration file. + + + + + + log_filename (string) + + log_filename configuration parameter + + + + When redirect_stderr is enabled, this option + sets the file names of the created log files. The value + is treated as a strftime pattern, + so %-escapes + can be used to specify time-varying file names. + If no %-escapes are present, + PostgreSQL will + append the epoch of the new log file's open time. For example, + if log_filename were server_log, then the + chosen file name would be server_log.1093827753 + for a log starting at Sun Aug 29 19:02:33 2004 MST. + This option can only be set at server start or in the + postgresql.conf configuration file. + + + + + + log_rotation_age (integer) + + log_rotation_age configuration parameter + + + + When redirect_stderr is enabled, this option + determines the maximum lifetime of an individual log file. + After this many minutes have elapsed, a new log file will + be created. Set to zero to disable time-based creation of + new log files. + This option can only be set at server start or in the + postgresql.conf configuration file. + + + + + + log_rotation_size (integer) + + log_rotation_size configuration parameter + + + + When redirect_stderr is enabled, this option + determines the maximum size of an individual log file. + After this many kilobytes have been emitted into a log file, + a new log file will be created. Set to zero to disable size-based + creation of new log files. + This option can only be set at server start or in the + postgresql.conf configuration file. + + + + + + log_truncate_on_rotation (boolean) + + log_truncate_on_rotation configuration parameter + + + + When redirect_stderr is enabled, this option will cause + PostgreSQL to truncate (overwrite), + rather than append to, any existing log file of the same name. + However, truncation will occur only when a new file is being opened + due to time-based rotation, not during server startup or size-based + rotation. When off, pre-existing files will be appended to in + all cases. For example, using this option in combination with + a log_filename like postgresql-%H.log + would result in generating twenty-four hourly log files and then + cyclically overwriting them. + This option can only be set at server start or in the + postgresql.conf configuration file. + + + Example: To keep 7 days of logs, one log file per day named + server_log.Mon, server_log.Tue, + etc, and automatically overwrite last week's log with this week's log, + set log_filename to server_log.%a, + log_truncate_on_rotation to on, and + log_rotation_age to 1440. + + + Example: To keep 24 hours of logs, one log file per hour, but + also rotate sooner if the log file size exceeds 1GB, set + log_filename to server_log.%H%M, + log_truncate_on_rotation to on, + log_rotation_age to 60, and + log_rotation_size to 1000000. + Including %M in log_filename allows + any size-driven rotations that may occur to select a filename + different from the hour's initial filename. + + + + + + syslog_facility (string) + + syslog_facility configuration parameter + + + + When logging to syslog is enabled, this option + determines the syslog + facility to be used. 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 daemon. + This option can only be set at server start. + + + + + + syslog_ident (string) + + syslog_identity configuration parameter + + + + When logging to syslog is enabled, this option + determines the program name used to identify + PostgreSQL messages in + syslog logs. The default is + postgres. + This option can only be set at server start. + + + + + + + + When To Log + + + + + client_min_messages (string) + + client_min_messages configuration parameter + + + + 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. + + + + + + log_min_messages (string) + + log_min_messages configuration parameter + + + + 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 change this setting. + + + + + + log_error_verbosity (string) + + log_error_verbosity configuration parameter + + + + 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. + Only superusers can change this setting. + + + + + + log_min_error_statement (string) + + log_min_error_statement configuration parameter + + + + 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 + higher 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 change this setting. + + + + + + log_min_duration_statement (integer) + + log_min_duration_statement configuration parameter + + + + Logs the statement and its duration on a single log line if its + duration is greater than or equal to the specified number of + milliseconds. Setting this to zero will print all statements + and their durations. Minus-one (the default) disables the + feature. 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. This setting is + independent of log_statement and + log_duration. Only superusers can change + this setting. + + + + + + silent_mode (boolean) + + silent_mode configuration parameter + + + + Runs the server silently. If this option is set, the server + will automatically run in background and any controlling + terminals are disassociated (same effect as + postmaster's option). + The server's standard output and standard error are redirected + to /dev/null, so any messages sent to them will be lost. + Unless syslog logging is selected or + redirect_stderr is enabled, using this option + is discouraged because it makes it impossible to see error messages. + + + + + + + + Here is a list of the various message severity levels used in + these settings: + + + DEBUG[1-5] + + + Provides information for use by developers. + + + + + + INFO + + + Provides information implicitly requested by the user, + e.g., during VACUUM VERBOSE. + + + + + + NOTICE + + + Provides information that may be helpful to users, e.g., + truncation of long identifiers and the creation of indexes as part + of primary keys. + + + + + + WARNING + + + Provides warnings to the user, e.g., COMMIT + outside a transaction block. + + + + + + ERROR + + + Reports an error that caused the current command to abort. + + + + + + LOG + + + Reports information of interest to administrators, e.g., + checkpoint activity. + + + + + + FATAL + + + Reports an error that caused the current session to abort. + + + + + + PANIC + + + Reports an error that caused all sessions to abort. + + + + + + + + + What To Log + + + + + debug_print_parse (boolean) + debug_print_rewritten (boolean) + debug_print_plan (boolean) + debug_pretty_print (boolean) + + debug_print_parse configuration parameter + + + debug_print_rewritten configuration parameter + + + debug_print_plan configuration parameter + + + debug_pretty_print configuration parameter + + + + These options enable various debugging output to be emitted. + 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 actually send this output + to the client or the server log, respectively. + These options are off by default. + + + + + + log_connections (boolean) + + log_connections configuration parameter + + + + This outputs a line to the server log 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. + + + + + + log_disconnections (boolean) + + log_disconnections configuration parameter + + + + This outputs a line in the server log similar to + log_connections but at session termination, + and includes the duration of the session. This is off by + default. This option can only be set at server start or in the + postgresql.conf configuration file. + + + + + + + log_duration (boolean) + + log_duration configuration parameter + + + + Causes the duration of every completed statement which satisfies + log_statement to be logged. When using this option, + if you are not using syslog, it is recommended + that you log the PID or session ID using log_line_prefix + so that you can link the statement to the + duration using the process ID or session ID. The default is + off. Only superusers can change this setting. + + + + + + log_line_prefix (string) + + log_line_prefix configuration parameter + + + + This is a printf-style string that is output at the + beginning of each log line. The default is an empty string. + Each recognized escape is replaced as outlined + below - anything else that looks like an escape is ignored. Other + characters are copied straight to the log line. Some escapes are + only recognised by session processes, and do not apply to + background processes such as the postmaster. Syslog + produces its own + time stamp and process ID information, so you probably do not want to + use those escapes if you are using syslog. + This option can only be set at server start or in the + postgresql.conf configuration file. + + + + + + Escape + Effect + Session only + + + + + %u + User name + yes + + + %d + Database name + yes + + + %r + Remote host name or IP address, and remote port + yes + + + %h + Remote Hostname or IP address + yes + + + %p + Process ID + no + + + %t + Time stamp (no milliseconds) + no + + + %m + Time stamp with milliseconds + no + + + %i + Command tag: This is the command that generated the log line. + yes + + + %c + Session ID: A unique identifier for each session. + It is 2 4-byte hexadecimal numbers (without leading zeros) + separated by a dot. The numbers + are the session start time and the process ID, so this can also + be used as a space saving way of printing these items. + yes + + + %l + Number of the log line for each process, starting at 1 + no + + + %s + Session start time stamp + yes + + + %x + Transaction ID + yes + + + %q + Does not produce any output, but tells non-session + processes to stop at this point in the string. Ignored by + session processes. + no + + + %% + Literal % + no + + + + + + + + + + log_statement (string) + + log_statement configuration parameter + + + + Controls which SQL statements are logged. Valid values are + none, ddl, mod, and + all. ddl logs all data definition + commands like CREATE, ALTER, and + DROP commands. mod logs all + ddl statements, plus INSERT, + UPDATE, DELETE, TRUNCATE, + and COPY FROM. PREPARE and + EXPLAIN ANALYZE statements are also logged if their + contained command is of an appropriate type. + + + The default is none. Only superusers can change this + setting. + + + + + The EXECUTE statement is not considered a + ddl or mod statement. When it is logged, + only the name of the prepared statement is reported, not the + actual prepared statement. + + + + When a function is defined in the + PL/pgSQLserver-side language, any queries + executed by the function will only be logged the first time that the + function is invoked in a particular session. This is because + PL/pgSQL keeps a cache of the + query plans produced for the SQL statements in the function. + + + + + + + log_hostname (boolean) + + log_hostname configuration parameter + + + + By default, connection log messages only show the IP address of the + connecting host. Turning on this option causes logging of the + host name as well. Note that depending on your host name resolution + setup this might impose a non-negligible performance penalty. This + option can only be set at server start or in the + postgresql.conf file. + + + + + + + + + + Runtime Statistics + + + Statistics Monitoring + + + + log_statement_stats (boolean) + log_parser_stats (boolean) + log_planner_stats (boolean) + log_executor_stats (boolean) + + log_statement_stats configuration parameter + + + log_parser_stats configuration parameter + + + log_planner_stats configuration parameter + + + log_executor_stats configuration parameter + + + + For each query, write performance statistics of the respective + module to the server log. This is a crude profiling + instrument. log_statement_stats reports total + statement statistics, while the others report per-module statistics. + log_statement_stats cannot be enabled together with + any of the per-module options. All of these options are disabled by + default. Only superusers can change these settings. + + + + + + + + + Query and Index Statistics Collector + + + + stats_start_collector (boolean) + + stats_start_collector configuration parameter + + + + 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. + + + + + + stats_command_string (boolean) + + stats_command_string configuration parameter + + + + 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 for more information. + + + + + + stats_block_level (boolean) + + stats_block_level configuration parameter + + + + Enables the collection of block-level statistics on database + activity. This option is disabled by default. If this option + is enabled, the data that is produced can be accessed via the + pg_stat and + pg_statio family of system views; + refer to for more information. + + + + + + stats_row_level (boolean) + + stats_row_level configuration parameter + + + + Enables the collection of row-level statistics on database + activity. This option is disabled by default. If this option + is enabled, the data that is produced can be accessed via the + pg_stat and + pg_statio family of system views; + refer to for more information. + + + + + + stats_reset_on_server_start (boolean) + + stats_reset_on_server_start configuration parameter + + + + If on, collected statistics are zeroed out whenever the server + is restarted. If off, statistics are accumulated across server + restarts. The default is off. This option can only + be set at server start. + + + + + + + + + + Automatic Vacuuming + + + Beginning in PostgreSQL 8.1, there is an optional server + process called the autovacuum daemon, whose purpose is + to automate the issuance of periodic VACUUM and + ANALYZE commands. When enabled, the autovacuum daemon + runs periodically and checks for tables that have had a large number + of updated or deleted tuples. This check uses the row-level statistics + collection facility; therefore, the autovacuum daemon cannot be used + unless and + are set TRUE. Also, it's + important to allow a slot for the autovacuum process when choosing + the value of . + + + + + + autovacuum (boolean) + + autovacuum configuration parameter + + + + Controls whether the server should start the + autovacuum subprocess. This is off by default. + This option can only be set at server start or in the + postgresql.conf file. + + + + + + autovacuum_naptime (integer) + + autovacuum_naptime configuration parameter + + + + Specifies the delay between activity rounds for the autovacuum + subprocess. In each round the subprocess examines one database + and issues VACUUM and ANALYZE commands + as needed for tables in that database. The delay is measured + in seconds, and the default is 60. + This option can only be set at server start or in the + postgresql.conf file. + + + + + + autovacuum_vacuum_threshold (integer) + + autovacuum_vacuum_threshold configuration parameter + + + + Specifies the minimum number of updated or deleted tuples needed + to trigger a VACUUM in any one table. + The default is 1000. + This option can only be set at server start or in the + postgresql.conf file. + + + + + + autovacuum_analyze_threshold (integer) + + autovacuum_analyze_threshold configuration parameter + + + + Specifies the minimum number of inserted, updated or deleted tuples + needed to trigger an ANALYZE in any one table. + The default is 500. + This option can only be set at server start or in the + postgresql.conf file. + + + + + + autovacuum_vacuum_scale_factor (floating point) + + autovacuum_vacuum_scale_factor configuration parameter + + + + Specifies a fraction of the table size to add to + autovacuum_vacuum_threshold + when deciding whether to trigger a VACUUM. + The default is 0.4. + This option can only be set at server start or in the + postgresql.conf file. + + + + + + autovacuum_analyze_scale_factor (floating point) + + autovacuum_analyze_scale_factor configuration parameter + + + + Specifies a fraction of the table size to add to + autovacuum_analyze_threshold + when deciding whether to trigger an ANALYZE. + The default is 0.2. + This option can only be set at server start or in the + postgresql.conf file. + + + + + + autovacuum_vacuum_cost_delay (integer) + + autovacuum_vacuum_cost_delay configuration parameter + + + + Specifies the cost delay value that will be used in automatic + VACUUM operations. If -1 is specified (which is the + default), the regular + value will be used. + This setting can be overridden for individual tables by entries in + pg_autovacuum. + + + + + + autovacuum_vacuum_cost_limit (integer) + + autovacuum_vacuum_cost_limit configuration parameter + + + + Specifies the cost limit value that will be used in automatic + VACUUM operations. If -1 is specified (which is the + default), the regular + value will be used. + This setting can be overridden for individual tables by entries in + pg_autovacuum. + + + + + + + + + Client Connection Defaults + + + Statement Behavior + + + + search_path (string) + + search_path configuration parameter + + pathfor schemas + + + 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 . + + + + + + default_tablespace (string) + + default_tablespace configuration parameter + + tablespacedefault + + + This variable specifies the default tablespace in which to create + objects (tables and indexes) when a CREATE command does + not explicitly specify a tablespace. + + + + The value is either the name of a tablespace, or an empty string + to specify using the default tablespace of the current database. + If the value does not match the name of any existing tablespace, + PostgreSQL will automatically use the default + tablespace of the current database. + + + + For more information on tablespaces, + see . + + + + + + check_function_bodies (boolean) + + check_function_bodies configuration parameter + + + + This parameter is normally on. When set to off, it + disables validation of the function body string during . Disabling validation is + occasionally useful to avoid problems such as forward references + when restoring function definitions from a dump. + + + + + + + transaction isolation level + + + default_transaction_isolation configuration parameter + + default_transaction_isolation (string) + + + Each SQL transaction has an isolation level, which can be + either read uncommitted, read + committed, repeatable read, or + serializable. This parameter controls the + default isolation level of each new transaction. The default + is read committed. + + + + Consult and for more information. + + + + + + + read-only transaction + + + default_transaction_read_only configuration parameter + + + default_transaction_read_only (boolean) + + + 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 off (read/write). + + + + Consult for more information. + + + + + + statement_timeout (integer) + + statement_timeout configuration parameter + + + + Abort any statement that takes over the specified number of + milliseconds. A value of zero (the default) turns off the limitation. + + + + + + + + Locale and Formatting + + + + + DateStyle (string) + + DateStyle configuration parameter + + + + 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 input/output specification for year/month/day ordering + (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 + for more information. The + default is ISO, MDY. + + + + + + timezone (string) + + timezone configuration parameter + + time zone + + + Sets the time zone for displaying and interpreting time + stamps. The default is 'unknown', which means to use whatever + the system environment specifies as the time zone. See for more information. + + + + + + australian_timezones (boolean) + + australian_timezones configuration parameter + + time zoneAustralian + + + If set to on, ACST, + CST, EST, and + SAT are interpreted as Australian time + zones rather than as North/South American time zones and + Saturday. The default is off. + + + + + + + significant digits + + + floating-point + display + + + extra_float_digits configuration parameter + + + extra_float_digits (integer) + + + 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. + + + + + + client_encoding (string) + + client_encoding configuration parameter + + character set + + + Sets the client-side encoding (character set). + The default is to use the database encoding. + + + + + + lc_messages (string) + + lc_messages configuration parameter + + + + Sets the language in which messages are displayed. Acceptable + values are system-dependent; see 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. + + + + + + lc_monetary (string) + + lc_monetary configuration parameter + + + + Sets the locale to use for formatting monetary amounts, for + example with the to_char family of + functions. Acceptable values are system-dependent; see 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. + + + + + + lc_numeric (string) + + lc_numeric configuration parameter + + + + Sets the locale to use for formatting numbers, for example + with the to_char family of + functions. Acceptable values are system-dependent; see 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. + + + + + + lc_time (string) + + lc_time configuration parameter + + + + 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 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. + + + + + + + + + Other Defaults + + + + + explain_pretty_print (boolean) + + explain_pretty_print configuration parameter + + + + Determines whether EXPLAIN VERBOSE uses the + indented or non-indented format for displaying detailed + query-tree dumps. The default is on. + + + + + + dynamic_library_path (string) + + dynamic_library_path configuration parameter + + dynamic loading + + + If a dynamically loadable module needs to be opened and the + file name specified in the CREATE FUNCTION or + LOAD command + does not have a directory component (i.e. the + name does not contain a slash), the system will search this + path for the required file. + + + + The value for dynamic_library_path has to be a + list of absolute directory paths separated by colons (or semi-colons + on Windows). If a list element starts + with the special string $libdir, the + compiled-in PostgreSQL package + library directory is substituted for $libdir. This + is where the modules provided by the standard + PostgreSQL distribution are installed. + (Use pg_config --pkglibdir to find out the name of + this directory.) For example: + +dynamic_library_path = '/usr/local/lib/postgresql:/home/my_project/lib:$libdir' + + or, in a Windows environment: + +dynamic_library_path = 'C:\tools\postgresql;H:\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. + + + + + + + + + + Lock Management + + + + + + deadlock + timeout during + + + timeout + deadlock + + + deadlock_timeout configuration parameter + + + 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. 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. + + + + + + max_locks_per_transaction (integer) + + max_locks_per_transaction configuration parameter + + + + The shared lock table is created with room to describe locks on + max_locks_per_transaction * + ( + + ) objects; + hence, no more than this many distinct objects can + be locked at any one time. (Thus, this parameter's name may be + confusing: it is not a hard limit on the number of locks taken + by any one transaction, but rather a maximum average value.) + 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. + + + + Increasing this parameter may cause PostgreSQL + to request more System V shared + memory than your operating system's default configuration + allows. See for information on how to + adjust those parameters, if necessary. + + + + + + + + + Version and Platform Compatibility + + + Previous PostgreSQL Versions + + + + add_missing_from (boolean) + FROMmissing + + add_missing_from configuration parameter + + + + When on, tables that are referenced by a query will be + automatically added to the FROM clause if not + already present. This behavior does not comply with the SQL + standard and many people dislike it because it can mask mistakes + (such as referencing a table where you should have referenced + its alias). The default is off. This variable can be + enabled for compatibility with releases of + PostgreSQL prior to 8.1, where this behavior was + allowed by default. + + + + Note that even when this variable is enabled, a warning + message will be emitted for each implicit FROM + entry referenced by a query. Users are encouraged to update + their applications to not rely on this behavior, by adding all + tables referenced by a query to the query's FROM + clause (or its USING clause in the case of + DELETE). + + + + + + regex_flavor (string) + regular expressions + + regex_flavor configuration parameter + + + + 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. See + for details. + + + + + + sql_inheritance (boolean) + + sql_inheritance configuration parameter + + inheritance + + + 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 for more information about + inheritance. + + + + + + default_with_oids (boolean) + + default_with_oids configuration parameter + + + + This controls whether CREATE TABLE and + CREATE TABLE AS include an OID column in + newly-created tables, if neither WITH OIDS + nor WITHOUT OIDS is specified. It also + determines whether OIDs will be included in tables created by + SELECT INTO. In PostgreSQL + 8.1 default_with_oids is disabled by default; in + prior versions of PostgreSQL, it was on by default. + + + + The use of OIDs in user tables is considered deprecated, so + most installations should leave this variable disabled. + Applications that require OIDs for a particular table should + specify WITH OIDS when creating the + table. This variable can be enabled for compatibility with old + applications that do not follow this behavior. + + + + + + escape_string_warning (boolean) + stringsescape + + escape_string_warning configuration parameter + + + + When on, a warning is issued if a backslash (\) + appears in an ordinary string literal ('...' + syntax). The default is off. + + + Escape string syntax (E'...') should be used for + escapes, because in future versions of + PostgreSQL ordinary strings will have + the standard-conforming behavior of treating backslashes + literally. + + + + + + + + Platform and Client Compatibility + + + + transform_null_equals (boolean) + IS NULL + + transform_null_equals configuration parameter + + + + When 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 SQL-spec-compliant 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 exact form = NULL, + 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 for related information. + + + + + + + + + + Preset Options + + + The following parameters are read-only, and are determined + when PostgreSQL is compiled or when it is + installed. As such, they have been excluded from the sample + postgresql.conf file. These options report + various aspects of PostgreSQL behavior + that may be of interest to certain applications, particularly + administrative front-ends. + + + + + + block_size (integer) + + block_size configuration parameter + + + + Reports the size of a disk block. It is determined by the value + of BLCKSZ when building the server. The default + value is 8192 bytes. The meaning of some configuration + variables (such as ) is + influenced by block_size. See for information. + + + + + + integer_datetimes (boolean) + + integer_datetimes configuration parameter + + + + Reports whether PostgreSQL was built + with support for 64-bit-integer dates and times. It is set by + configuring with --enable-integer-datetimes + when building PostgreSQL. The + default value is off. + + + + + + lc_collate (string) + + lc_collate configuration parameter + + + + Reports the locale in which sorting of textual data is done. + See for more information. + The value is determined when the database cluster is initialized. + + + + + + lc_ctype (string) + + lc_ctype configuration parameter + + + + Reports the locale that determines character classifications. + See for more information. + The value is determined when the database cluster is initialized. + Ordinarily this will be the same as lc_collate, + but for special applications it might be set differently. + + + + + + max_function_args (integer) + + max_function_args configuration parameter + + + + Reports the maximum number of function arguments. It is determined by + the value of FUNC_MAX_ARGS when building the server. The + default value is 100. + + + + + + max_identifier_length (integer) + + max_identifier_length configuration parameter + + + + Reports the maximum identifier length. It is determined as one + less than the value of NAMEDATALEN when building + the server. The default value of NAMEDATALEN is + 64; therefore the default + max_identifier_length is 63. + + + + + + max_index_keys (integer) + + max_index_keys configuration parameter + + + + Reports the maximum number of index keys. It is determined by + the value of INDEX_MAX_KEYS when building the server. The + default value is 32. + + + + + + server_encoding (string) + + server_encoding configuration parameter + + character set + + + Reports the database encoding (character set). + It is determined when the database is created. Ordinarily, + clients need only be concerned with the value of . + + + + + + server_version (string) + + server_version configuration parameter + + + + Reports the version number of the server. It is determined by the + value of PG_VERSION when building the server. + + + + + + standard_conforming_strings (boolean) + stringsescape + + standard_conforming_strings configuration parameter + + + + Reports whether ordinary string literals + ('...') treat backslashes literally, as specified in + the SQL standard. The value is currently always off, + indicating that backslashes are treated as escapes. It is planned + that this will change to on in a future + PostgreSQL release when string literal + syntax changes to meet the standard. Applications may check this + parameter to determine how string literals will be processed. + The presence of this parameter can also be taken as an indication + that the escape string syntax (E'...') is supported. + + + + + + + + + Customized Options + + + This feature was designed to allow options not normally known to + PostgreSQL to be added by add-on modules + (such as procedural languages). This allows add-on modules to be + configured in the standard ways. + + + + + + custom_variable_classes (string) + + custom_variable_classes configuration parameter + + + + This variable specifies one or several class names to be used for + custom variables, in the form of a comma-separated list. A custom + variable is a variable not normally known + to PostgreSQL proper but used by some + add-on module. Such variables must have names consisting of a class + name, a dot, and a variable name. custom_variable_classes + specifies all the class names in use in a particular installation. + This option can only be set at server start or in the + postgresql.conf configuration file. + + + + + + + + The difficulty with setting custom variables in + postgresql.conf is that the file must be read before add-on + modules have been loaded, and so custom variables would ordinarily be + rejected as unknown. When custom_variable_classes is set, + the server will accept definitions of arbitrary variables within each + specified class. These variables will be treated as placeholders and + will have no function until the module that defines them is loaded. When a + module for a specific class is loaded, it will add the proper variable + definitions for its class name, convert any placeholder + values according to those definitions, and issue warnings for any + placeholders of its class that remain (which presumably would be + misspelled configuration variables). + + + + Here is an example of what postgresql.conf might contain + when using custom variables: + + +custom_variable_classes = 'plr,plperl' +plr.path = '/usr/lib/R' +plperl.use_strict = true +plruby.use_strict = true # generates error: unknown class name + + + + + + Developer Options + + + 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. + + + + + debug_assertions (boolean) + + debug_assertions configuration parameter + + + + 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 + ). Note that + debug_assertions defaults to on + if PostgreSQL has been built with + assertions enabled. + + + + + + pre_auth_delay (integer) + + pre_auth_delay configuration parameter + + + + 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. + + + + + + trace_notify (boolean) + + trace_notify configuration parameter + + + + Generates a great amount of debugging output for the + LISTEN and NOTIFY + commands. or + must be + DEBUG1 or lower to send this output to the + client or server log, respectively. + + + + + + trace_locks (boolean) + trace_lwlocks (boolean) + trace_userlocks (boolean) + trace_lock_oidmin (boolean) + trace_lock_table (boolean) + debug_deadlocks (boolean) + log_btree_build_stats (boolean) + + + Various other code tracing and debugging options. + + + + + + wal_debug (boolean) + + wal_debug configuration parameter + + + + If on, emit WAL-related debugging output. This option is + only available if the WAL_DEBUG macro was + defined when PostgreSQL was + compiled. + + + + + + zero_damaged_pages (boolean) + + zero_damaged_pages configuration parameter + + + + Detection of a damaged page header normally causes + PostgreSQL to report an error, aborting the current + command. Setting zero_damaged_pages to on 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 on 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. + + + + + + + Short Options + + + For convenience there are also single letter command-line option switches + available for some parameters. They are described in . + + + + Short option key + + + + Short option + Equivalent + + + + + + + shared_buffers = x + + + + log_min_messages = DEBUGx + + + + fsync = off + + + + listen_addresses = x + + + + listen_addresses = '*' + + + + unix_socket_directory = x + + + + ssl = on + + + + max_connections = x + + + + port = x + + + + + , , , + , , + , + + For historical reasons, these options must be passed to + the individual server process via the + postmaster option, for example, + +$ postmaster -o '-S 1024 -s' + + or via PGOPTIONS from the client side, as + explained above. + + + + + enable_bitmapscan = off, + enable_hashjoin = off, + enable_indexscan = off, + enable_mergejoin = off, + enable_nestloop = off, + enable_seqscan = off, + enable_tidscan = off + + + + + + log_statement_stats = on + + + + + + work_mem = x + + + + , , + log_parser_stats = on, + log_planner_stats = on, + log_executor_stats = on + + + +
+ +
+
+ + diff --git a/doc/src/sgml/filelist.sgml b/doc/src/sgml/filelist.sgml index 88487ee938..3b1cd74005 100644 --- a/doc/src/sgml/filelist.sgml +++ b/doc/src/sgml/filelist.sgml @@ -1,4 +1,4 @@ - + @@ -41,6 +41,7 @@ + diff --git a/doc/src/sgml/postgres.sgml b/doc/src/sgml/postgres.sgml index 6fa0e28191..8099f72dd8 100644 --- a/doc/src/sgml/postgres.sgml +++ b/doc/src/sgml/postgres.sgml @@ -1,5 +1,5 @@ @@ -451,4224 +451,6 @@ psql: could not connect to server: No such file or directory - - Run-time Configuration - - - configuration - of the server - - - - 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 four types: boolean, integer, floating point, - or string. Boolean values may be written as ON, - OFF, TRUE, - FALSE, YES, - NO, 1, 0 - (all case-insensitive) or any unambiguous prefix of these. - - - - One way to set these parameters is to edit the file - postgresql.confpostgresql.conf, - which is normally kept in the data directory. (initdb - installs a default copy there.) An example of what this file might look - like is: - -# This is a comment -log_connections = yes -log_destination = 'syslog' -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 must be single-quoted. - - - - - SIGHUP - - 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. 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. - - - - 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 log_destination='syslog' - - Command-line options override any conflicting settings in - postgresql.conf. Note that this means you won't - be able to change the value on-the-fly by editing - postgresql.conf, so while the command-line - method may be convenient, it can cost you flexibility later. - - - - Occasionally it is 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 or that must be - specified in postgresql.conf. - - - - 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 - and , - 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 - command, for example: - -SET ENABLE_SEQSCAN TO OFF; - - If SET is allowed, it overrides all other sources of - values for the parameter. Some parameters cannot be changed via - SET: for example, if they control behavior that - cannot reasonably be changed without restarting - PostgreSQL. Also, some parameters can - be modified via SET or ALTER by superusers, - but not by ordinary users. - - - - The - command allows inspection of the current values of all parameters. - - - - The virtual table pg_settings - (described in ) 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. - - - - File Locations - - - In addition to the postgresql.conf file - already mentioned, PostgreSQL uses - two other manually-edited configuration files, which control - client authentication (their use is discussed in ). - By default, all three configuration files are stored - in the database cluster's data directory. The options described - in this subsection allow the configuration files to be placed elsewhere. - (Doing so can ease administration. In particular it is often - easier to ensure that the configuration files are properly backed-up - when they are kept separate.) - - - - - data_directory (string) - - data_directory configuration parameter - - - - Specifies the directory to use for data storage. - This option can only be set at server start. - - - - - - config_file (string) - - config_file configuration parameter - - - - Specifies the main server configuration file - (customarily called postgresql.conf). - This option can only be set on the postmaster command line. - - - - - - hba_file (string) - - hba_file configuration parameter - - - - Specifies the configuration file for host-based authentication - (customarily called pg_hba.conf). - This option can only be set at server start. - - - - - - ident_file (string) - - ident_file configuration parameter - - - - Specifies the configuration file for - ident authentication - (customarily called pg_ident.conf). - This option can only be set at server start. - - - - - - external_pid_file (string) - - external_pid_file configuration parameter - - - - Specifies the name of an additional process-id (PID) file that the - postmaster should create for use by server - administration programs. - This option can only be set at server start. - - - - - - - In a default installation, none of the above options are set explicitly. - Instead, the - data directory is specified by the command-line - option or the PGDATA environment variable, and the - configuration files are all found within the data directory. - - - - If you wish to keep the configuration files elsewhere than the - data directory, the postmaster's - command-line option or PGDATA environment variable - must point to the directory containing the configuration files, - and the data_directory option must be set in - postgresql.conf (or on the command line) to show - where the data directory is actually located. Notice that - data_directory overrides and - PGDATA for the location - of the data directory, but not for the location of the configuration - files. - - - - If you wish, you can specify the configuration file names and locations - individually using the options config_file, - hba_file and/or ident_file. - config_file can only be specified on the - postmaster command line, but the others can be - set within the main configuration file. If all three options plus - data_directory are explicitly set, then it is not necessary - to specify or PGDATA. - - - - When setting any of these options, a relative path will be interpreted - with respect to the directory in which the postmaster - is started. - - - - - Connections and Authentication - - - Connection Settings - - - - - listen_addresses (string) - - listen_addresses configuration parameter - - - - Specifies the TCP/IP address(es) on which the server is - to listen for connections from client applications. - The value takes the form of a comma-separated list of host names - and/or numeric IP addresses. The special entry * - corresponds to all available IP interfaces. - If the list is empty, the server does not listen on any IP interface - at all, in which case only Unix-domain sockets can be used to connect - to it. - The default value is localhost, - which allows only local loopback connections to be made. - This parameter can only be set at server start. - - - - - - port (integer) - - port configuration parameter - - - - The TCP port the server listens on; 5432 by default. Note that the - same port number is used for all IP addresses the server listens on. - This parameter can only be set at server start. - - - - - - max_connections (integer) - - max_connections configuration parameter - - - - 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 for information on how to - adjust those parameters, if necessary. - - - - - - superuser_reserved_connections - (integer) - - superuser_reserved_connections configuration parameter - - - - Determines the number of connection slots that - are reserved for connections by PostgreSQL - superusers. At most - 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. - - - - - - unix_socket_directory (string) - - unix_socket_directory configuration parameter - - - - 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. - This parameter can only be set at server start. - - - - - - unix_socket_group (string) - - unix_socket_group configuration parameter - - - - Sets the owning group of the Unix-domain socket. (The owning - user of the socket is always the user that starts the - server.) In combination with the option - unix_socket_permissions this can be used as - an additional access control mechanism for Unix-domain connections. - By default this is the empty string, which uses the default - group for the current user. This option can only be set at - server start. - - - - - - unix_socket_permissions (integer) - - unix_socket_permissions configuration parameter - - - - 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 are - 0770 (only user and group, see also - unix_socket_group) and 0700 - (only user). (Note that for a Unix-domain socket, only write - permission matters and so there is no point in setting or revoking - read or execute permissions.) - - - - This access control mechanism is independent of the one - described in . - - - - This option can only be set at server start. - - - - - - bonjour_name (string) - - bonjour_name configuration parameter - - - - Specifies the Bonjour broadcast - name. By default, the computer name is used, specified as an - empty string ''. This option is ignored if the server was not - compiled with Bonjour support. This - option can only be set at server start. - - - - - - tcp_keepalives_idle (integer) - - tcp_keepalives_idle configuration parameter - - - - On systems that support the TCP_KEEPIDLE socket option, specifies the - number of seconds between sending keepalives on an otherwise idle - connection. A value of 0 uses the system default. If TCP_KEEPIDLE is - not supported, this parameter must be 0. This option is ignored for - connections made via a Unix-domain socket. - - - - - - tcp_keepalives_interval (integer) - - tcp_keepalives_interval configuration parameter - - - - On systems that support the TCP_KEEPINTVL socket option, specifies how - long, in seconds, to wait for a response to a keepalive before - retransmitting. A value of 0 uses the system default. If TCP_KEEPINTVL - is not supported, this parameter must be 0. This option is ignored - for connections made via a Unix-domain socket. - - - - - - tcp_keepalives_count (integer) - - tcp_keepalives_count configuration parameter - - - - On systems that support the TCP_KEEPCNT socket option, specifies how - many keepalives may be lost before the connection is considered dead. - A value of 0 uses the system default. If TCP_KEEPINTVL is not - supported, this parameter must be 0. - - - - - - - - Security and Authentication - - - - authentication_timeout (integer) - timeoutclient authentication - client authenticationtimeout during - - authentication_timeout configuration parameter - - - - - 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. - - - - - - ssl (boolean) - - ssl configuration parameter - - - - Enables SSL connections. Please read - before using this. The default - is off. This parameter can only be set at server - start. - - - - - - password_encryption (boolean) - - password_encryption configuration parameter - - - - When a password is specified in or - - without writing either ENCRYPTED or - UNENCRYPTED, this option determines whether the - password is to be encrypted. The default is on - (encrypt the password). - - - - - - krb_server_keyfile (string) - - krb_server_keyfile configuration parameter - - - - Sets the location of the Kerberos server key file. See - for details. This parameter - can only be set at server start. - - - - - - krb_srvname (string) - - krb_srvname configuration parameter - - - - Sets the Kerberos service name. See - for details. This parameter can only be set at server start. - - - - - - krb_server_hostname (string) - - krb_server_hostname configuration parameter - - - - Sets the hostname part of the service principal. - This, combined with krb_srvname, is used to generate - the complete service principal, i.e. - krb_server_hostname/krb_server_hostname@REALM. - - - If not set, the default is to allow any service principal matching an entry - in the keytab. See for details. - This parameter can only be set at server start. - - - - - - krb_caseins_users (boolean) - - krb_caseins_users configuration parameter - - - - Sets if Kerberos usernames should be treated case-insensitively. - The default is off (case sensitive). This parameter - can only be set at server start. - - - - - - db_user_namespace (boolean) - - db_user_namespace configuration parameter - - - - This enables 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 are appended to the user - name and that database-specific user name is looked up by the - server. Note that when you create users with names containing - @ 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. - - - - - This feature is intended as a temporary measure until a - complete solution is found. At that time, this option will - be removed. - - - - - - - - - - - Resource Consumption - - - Memory - - - - shared_buffers (integer) - - shared_buffers configuration parameter - - - - 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 ; - 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 for information on how to - adjust those parameters, if necessary. - - - - - - temp_buffers (integer) - - temp_buffers configuration parameter - - - - Sets the maximum number of temporary buffers used by each database - session. These are session-local buffers used only for access - to temporary tables. The default is 1000. The setting can - be changed within individual sessions, but only up until the - first use of temporary tables within a session; subsequent - attempts to change the value will have no effect on that session. - - - - A session will allocate temporary buffers as needed up to the limit - given by temp_buffers. The cost of setting a large - value in sessions that do not actually need a lot of temporary - buffers is only a buffer descriptor, or about 64 bytes, per - increment in temp_buffers. However if a buffer is - actually used an additional 8192 bytes will be consumed for it - (or in general, BLCKSZ bytes). - - - - - - max_prepared_transactions (integer) - - max_prepared_transactions configuration parameter - - - - Sets the maximum number of transactions that can be in the - prepared state simultaneously (see ). - Setting this parameter to zero disables the prepared-transaction - feature. - The default is 5. - This option can only be set at server start. - - - - If you are not using prepared transactions, this parameter may as - well be set to zero. If you are using them, you will probably - want max_prepared_transactions to be at least - as large as , to avoid unwanted - failures at the prepare step. - - - - Increasing this parameter may cause PostgreSQL - to request more System V shared - memory than your operating system's default configuration - allows. See for information on how to - adjust those parameters, if necessary. - - - - - - work_mem (integer) - - work_mem configuration parameter - - - - 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 such operations - concurrently. So the total memory used could be many - times the value of work_mem; it is necessary to - keep this fact in mind when choosing the value. Sort operations are - used for ORDER BY, DISTINCT, and - merge joins. - Hash tables are used in hash joins, hash-based aggregation, and - hash-based processing of IN subqueries. - - - - - - maintenance_work_mem (integer) - - maintenance_work_mem configuration parameter - - - - Specifies the maximum amount of memory to be used in maintenance - operations, such as VACUUM, CREATE - INDEX, and ALTER TABLE ADD FOREIGN KEY. - The value is specified in kilobytes, and defaults to 16384 kilobytes - (16 MB). Since only one of these operations can be executed at - a time by a database session, and an installation normally doesn't - have very many of them happening concurrently, it's safe to set this - value significantly larger than work_mem. Larger - settings may improve performance for vacuuming and for restoring - database dumps. - - - - - - max_stack_depth (integer) - - max_stack_depth configuration parameter - - - - Specifies the maximum safe depth of the server's execution stack. - The ideal setting for this parameter is the actual stack size limit - enforced by the kernel (as set by ulimit -s or local - equivalent), less a safety margin of a megabyte or so. The safety - margin is needed because the stack depth is not checked in every - routine in the server, but only in key potentially-recursive routines - such as expression evaluation. Setting the parameter higher than - the actual kernel limit will mean that a runaway recursive function - can crash an individual backend process. The default setting is - 2048 KB (two megabytes), which is conservatively small and unlikely - to risk crashes. However, it may be too small to allow execution - of complex functions. - - - - - - - - Free Space Map - - - free space map - - - - These parameters control the size of the shared free space - map, which tracks the locations of unused space in the database. - An undersized free space map may cause the database to consume - increasing amounts of disk space over time, because free space that - is not in the map cannot be re-used; instead PostgreSQL - will request more disk space from the operating system when it needs - to store new data. - The last few lines displayed by a database-wide VACUUM VERBOSE - command can help in determining if the current settings are adequate. - A NOTICE message is also printed during such an operation - if the current settings are too low. - - - - Increasing these parameters may cause PostgreSQL - to request more System V shared - memory than your operating system's default configuration - allows. See for information on how to - adjust those parameters, if necessary. - - - - - max_fsm_pages (integer) - - max_fsm_pages configuration parameter - - - - 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. - - - - - - max_fsm_relations (integer) - - max_fsm_relations configuration parameter - - - - Sets the maximum number of relations (tables and indexes) for which - free space will be tracked in the shared free-space map. Roughly - seventy bytes of shared memory are consumed for each slot. - The default is 1000. - This option can only be set at server start. - - - - - - - - Kernel Resource Usage - - - - max_files_per_process (integer) - - max_files_per_process configuration parameter - - - - 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. - - - - - - preload_libraries (string) - - preload_libraries configuration parameter - - - - 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 a specified library or initialization function is 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 slightly, even if that process never - uses the library. So this option is recommended only for - libraries that will be used in most sessions. - - - - - - - - - - Cost-Based Vacuum Delay - - - - During the execution of and commands, the system maintains an - internal counter that keeps track of the estimated cost of the - various I/O operations that are performed. When the accumulated - cost reaches a limit (specified by - vacuum_cost_limit), the process performing - the operation will sleep for a while (specified by - vacuum_cost_delay). Then it will reset the - counter and continue execution. - - - - The intent of this feature is to allow administrators to reduce - the I/O impact of these commands on concurrent database - activity. There are many situations in which it is not very - important that maintenance commands like - VACUUM and ANALYZE finish - quickly; however, it is usually very important that these - commands do not significantly interfere with the ability of the - system to perform other database operations. Cost-based vacuum - delay provides a way for administrators to achieve this. - - - - This feature is disabled by default. To enable it, set the - vacuum_cost_delay variable to a nonzero - value. - - - - - vacuum_cost_delay (integer) - - vacuum_cost_delay configuration parameter - - - - The length of time, in milliseconds, that the process will sleep - when the cost limit has been exceeded. - The default value is 0, which disables the cost-based vacuum - delay feature. Positive values enable cost-based vacuuming. - Note that on many systems, the effective resolution - of sleep delays is 10 milliseconds; setting - vacuum_cost_delay to a value that is - not a multiple of 10 may have the same results as setting it - to the next higher multiple of 10. - - - - - - vacuum_cost_page_hit (integer) - - vacuum_cost_page_hit configuration parameter - - - - The estimated cost for vacuuming a buffer found in the shared buffer - cache. It represents the cost to lock the buffer pool, lookup - the shared hash table and scan the content of the page. The - default value is 1. - - - - - - vacuum_cost_page_miss (integer) - - vacuum_cost_page_miss configuration parameter - - - - The estimated cost for vacuuming a buffer that has to be read from - disk. This represents the effort to lock the buffer pool, - lookup the shared hash table, read the desired block in from - the disk and scan its content. The default value is 10. - - - - - - vacuum_cost_page_dirty (integer) - - vacuum_cost_page_dirty configuration parameter - - - - The estimated cost charged when vacuum modifies a block that was - previously clean. It represents the extra I/O required to - flush the dirty block out to disk again. The default value is - 20. - - - - - - vacuum_cost_limit (integer) - - vacuum_cost_limit configuration parameter - - - - The accumulated cost that will cause the vacuuming process to sleep. - The default value is 200. - - - - - - - - There are certain operations that hold critical locks and should - therefore complete as quickly as possible. Cost-based vacuum - delays do not occur during such operations. Therefore it is - possible that the cost accumulates far higher than the specified - limit. To avoid uselessly long delays in such cases, the actual - delay is calculated as vacuum_cost_delay * - accumulated_balance / - vacuum_cost_limit with a maximum of - vacuum_cost_delay * 4. - - - - - - - Background Writer - - - Beginning in PostgreSQL 8.0, there is a separate server - process called the background writer, whose sole function - is to issue writes of dirty shared buffers. The intent is - that server processes handling user queries should seldom or never have - to wait for a write to occur, because the background writer will do it. - This arrangement also reduces the performance penalty associated with - checkpoints. The background writer will continuously trickle out dirty - pages to disk, so that only a few pages will need to be forced out when - checkpoint time arrives, instead of the storm of dirty-buffer writes that - formerly occurred at each checkpoint. However there is a net overall - increase in I/O load, because where a repeatedly-dirtied page might - before have been written only once per checkpoint interval, the - background writer might write it several times in the same interval. - In most situations a continuous low load is preferable to periodic - spikes, but the parameters discussed in this section can be used to tune - the behavior for local needs. - - - - - bgwriter_delay (integer) - - bgwriter_delay configuration parameter - - - - Specifies the delay between activity rounds for the - background writer. In each round the writer issues writes - for some number of dirty buffers (controllable by the - following parameters). It then sleeps for bgwriter_delay - milliseconds, and repeats. The default value is 200. Note - that on many systems, the effective resolution of sleep - delays is 10 milliseconds; setting bgwriter_delay - to a value that is not a multiple of 10 may have the same - results as setting it to the next higher multiple of 10. - This option can only be set at server start or in the - postgresql.conf file. - - - - - - bgwriter_lru_percent (floating point) - - bgwriter_lru_percent configuration parameter - - - - To reduce the probability that server processes will need to issue - their own writes, the background writer tries to write buffers that - are likely to be recycled soon. In each round, it examines up to - bgwriter_lru_percent of the buffers that are nearest to - being recycled, and writes any that are dirty. - The default value is 1.0 (this is a percentage of the total number - of shared buffers). - This option can only be set at server start or in the - postgresql.conf file. - - - - - - bgwriter_lru_maxpages (integer) - - bgwriter_lru_maxpages configuration parameter - - - - In each round, no more than this many buffers will be written - as a result of scanning soon-to-be-recycled buffers. - The default value is 5. - This option can only be set at server start or in the - postgresql.conf file. - - - - - - bgwriter_all_percent (floating point) - - bgwriter_all_percent configuration parameter - - - - To reduce the amount of work that will be needed at checkpoint time, - the background writer also does a circular scan through the entire - buffer pool, writing buffers that are found to be dirty. - In each round, it examines up to - bgwriter_all_percent of the buffers for this purpose. - The default value is 0.333 (this is a percentage of the total number - of shared buffers). With the default bgwriter_delay - setting, this will allow the entire shared buffer pool to be scanned - about once per minute. - This option can only be set at server start or in the - postgresql.conf file. - - - - - - bgwriter_all_maxpages (integer) - - bgwriter_all_maxpages configuration parameter - - - - In each round, no more than this many buffers will be written - as a result of the scan of the entire buffer pool. (If this - limit is reached, the scan stops, and resumes at the next buffer - during the next round.) - The default value is 5. - This option can only be set at server start or in the - postgresql.conf file. - - - - - - - Smaller values of bgwriter_all_percent and - bgwriter_all_maxpages reduce the extra I/O load - caused by the background writer, but leave more work to be done - at checkpoint time. To reduce load spikes at checkpoints, - increase these two values. - Similarly, smaller values of bgwriter_lru_percent and - bgwriter_lru_maxpages reduce the extra I/O load - caused by the background writer, but make it more likely that server - processes will have to issue writes for themselves, delaying interactive - queries. - To disable background writing entirely, - set both maxpages values and/or both - percent values to zero. - - - - - - - Write Ahead Log - - - See also for details on WAL - tuning. - - - - Settings - - - - - fsync configuration parameter - - fsync (boolean) - - - 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. - - - - 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. - (Crashes of the database server itself are not - a risk factor here. Only an operating-system-level crash - creates a risk of corruption.) - - - - 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. If this option - is off, consider also turning off - guc-full-page-writes. - - - - - - wal_sync_method (string) - - wal_sync_method configuration parameter - - - - Method used for forcing WAL updates out to disk. Possible - values are: - - - - - open_datasync (write WAL files with open() option O_DSYNC) - - - - - fdatasync (call fdatasync() at each commit), - - - - - fsync (call fsync() at each commit) - - - - - fsync_writethrough (force write-through of any disk write cache) - - - - - open_sync (write WAL files with open() option O_SYNC) - - - - - Not all of these choices are available on all platforms. - The top-most supported option is used as the default. - If fsync is off then this setting is irrelevant. - This option can only be set at server start or in the - postgresql.conf file. - - - - - - - full_page_writes configuration parameter - - full_page_writes (boolean) - - - A page write in process during an operating system crash might - be only partially written to disk, leading to an on-disk page - that contains a mix of old and new data. During recovery, the - row changes stored in WAL are not enough to completely restore - the page. - - - - When this option is on, the PostgreSQL server - writes full pages to WAL when they are first modified after a - checkpoint so full recovery is possible. Turning this option off - might lead to a corrupt system after an operating system crash - or power failure because uncorrected partial pages might contain - inconsistent or corrupt data. The risks are less but similar to - fsync. - - - - This option can only be set at server start or in the - postgresql.conf file. The default is - on. - - - - - - wal_buffers (integer) - - wal_buffers configuration parameter - - - - Number of disk-page buffers allocated in shared memory for WAL data. - The default is 8. The setting need only be large enough to hold - the amount of WAL data generated by one typical transaction, since - the data is flushed to disk at every transaction commit. - 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 for information on how to - adjust those parameters, if necessary. - - - - - - commit_delay (integer) - - commit_delay configuration parameter - - - - Time delay between writing a commit record to the WAL buffer - and flushing the buffer out to disk, in microseconds. A - nonzero delay can allow multiple transactions to be committed - with only one fsync() system call, if - system load is high enough that additional transactions become - ready to commit within the given interval. But the delay is - just wasted if no other transactions become ready to - commit. Therefore, the delay is only performed if at least - commit_siblings other transactions are - active at the instant that a server process has written its - commit record. The default is zero (no delay). - - - - - - commit_siblings (integer) - - commit_siblings configuration parameter - - - - 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. - - - - - - - - Checkpoints - - - - checkpoint_segments (integer) - - checkpoint_segments configuration parameter - - - - 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. - - - - - - checkpoint_timeout (integer) - - checkpoint_timeout configuration parameter - - - - 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. - - - - - - checkpoint_warning (integer) - - checkpoint_warning configuration parameter - - - - Write a message to the server log if checkpoints caused by - the filling of checkpoint segment files happen closer together - than this many seconds. The default is 30 seconds. - Zero turns off the warning. - - - - - - - - Archiving - - - - archive_command (string) - - archive_command configuration parameter - - - - The shell command to execute to archive a completed segment of - the WAL file series. If this is an empty string (the default), - WAL archiving is disabled. Any %p in the string is - replaced by the absolute path of the file to archive, and any - %f is replaced by the file name only. Use - %% to embed an actual % character in the - command. For more information see . This option can only be set at - server start or in the postgresql.conf - file. - - - It is important for the command to return a zero exit status if - and only if it succeeds. Examples: - -archive_command = 'cp "%p" /mnt/server/archivedir/"%f"' -archive_command = 'copy "%p" /mnt/server/archivedir/"%f"' # Windows - - - - - - - - - - - Query Planning - - - Planner Method Configuration - - - These configuration parameters provide a crude method of - influencing the query plans chosen by the query optimizer. If - the default plan chosen by the optimizer for a particular query - is not optimal, a temporary solution may be found by using one - of these configuration parameters to force the optimizer to - choose a different plan. Turning one of these settings off - permanently is seldom a good idea, however. - Better ways to improve the quality of the - plans chosen by the optimizer include adjusting the , running more - frequently, increasing the value of the configuration parameter, - and increasing the amount of statistics collected for - specific columns using ALTER TABLE SET - STATISTICS. - - - - - enable_bitmapscan (boolean) - - bitmap scan - - - enable_bitmapscan configuration parameter - - - - Enables or disables the query planner's use of bitmap-scan plan - types. The default is on. - - - - - - enable_hashagg (boolean) - - enable_hashagg configuration parameter - - - - Enables or disables the query planner's use of hashed - aggregation plan types. The default is on. - - - - - - enable_hashjoin (boolean) - - enable_hashjoin configuration parameter - - - - Enables or disables the query planner's use of hash-join plan - types. The default is on. - - - - - - enable_indexscan (boolean) - - index scan - - - enable_indexscan configuration parameter - - - - Enables or disables the query planner's use of index-scan plan - types. The default is on. - - - - - - enable_mergejoin (boolean) - - enable_mergejoin configuration parameter - - - - Enables or disables the query planner's use of merge-join plan - types. The default is on. - - - - - - enable_nestloop (boolean) - - enable_nestloop configuration parameter - - - - 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. - - - - - - enable_seqscan (boolean) - - sequential scan - - - enable_seqscan configuration parameter - - - - 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. - - - - - - enable_sort (boolean) - - enable_sort configuration parameter - - - - 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. - - - - - - enable_tidscan (boolean) - - enable_tidscan configuration parameter - - - - Enables or disables the query planner's use of TID - scan plan types. The default is on. - - - - - - - - - Planner Cost Constants - - - - - 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. - - - - - - - effective_cache_size (floating point) - - effective_cache_size configuration parameter - - - - Sets the planner's assumption about the effective size of the - disk cache that is available to a single index scan. This is - factored into estimates of the cost of using an index; a higher - value makes it more likely index scans will be used, a lower - value makes it more likely sequential scans will be used. When - setting this parameter you should consider both - PostgreSQL's shared buffers and the - portion of the kernel's disk cache that will be used for - PostgreSQL data files. Also, take into - account the expected number of concurrent queries using different - indexes, since they will have to share the available space. - This parameter has no effect on the size of shared memory - allocated by PostgreSQL, nor does it reserve kernel disk cache; - it is used only for estimation purposes. - The value is measured in disk pages, which are - normally 8192 bytes each. The default is 1000. - - - - - - random_page_cost (floating point) - - random_page_cost configuration parameter - - - - Sets the 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. - - - - - - cpu_tuple_cost (floating point) - - cpu_tuple_cost configuration parameter - - - - Sets the 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. - - - - - - cpu_index_tuple_cost (floating point) - - cpu_index_tuple_cost configuration parameter - - - - Sets the 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. - - - - - - cpu_operator_cost (floating point) - - cpu_operator_cost configuration parameter - - - - 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. - - - - - - - - - Genetic Query Optimizer - - - - - - genetic query optimization - - - GEQO - genetic query optimization - - - geqo configuration parameter - - geqo (boolean) - - - Enables or disables genetic query optimization, which is an - algorithm that attempts to do query planning without - exhaustive searching. This is on by default. The - geqo_threshold variable provides a more - granular way to disable GEQO for certain classes of queries. - - - - - - geqo_threshold (integer) - - geqo_threshold configuration parameter - - - - 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 12. For simpler queries it is usually best - to use the deterministic, exhaustive planner, but for queries with - many tables the deterministic planner takes too long. - - - - - - geqo_effort - (integer) - - geqo_effort configuration parameter - - - - Controls the trade off between planning time and query plan - efficiency in GEQO. This variable must be an integer in the - range from 1 to 10. The default value is 5. Larger values - increase the time spent doing query planning, but also - increase the likelihood that an efficient query plan will be - chosen. - - - - geqo_effort doesn't actually do anything - directly; it is only used to compute the default values for - the other variables that influence GEQO behavior (described - below). If you prefer, you can set the other parameters by - hand instead. - - - - - - geqo_pool_size (integer) - - geqo_pool_size configuration parameter - - - - Controls the pool size used by GEQO. The pool size is the - number of individuals in the genetic population. It must be - at least two, and useful values are typically 100 to 1000. If - it is set to zero (the default setting) then a suitable - default is chosen based on geqo_effort and - the number of tables in the query. - - - - - - geqo_generations (integer) - - geqo_generations configuration parameter - - - - Controls the number of generations used by GEQO. Generations - specifies the number of iterations of the algorithm. It must - be at least one, and useful values are in the same range as - the pool size. If it is set to zero (the default setting) - then a suitable default is chosen based on - geqo_pool_size. - - - - - - geqo_selection_bias (floating point) - - geqo_selection_bias configuration parameter - - - - Controls the selection bias used by GEQO. The selection bias - is the selective pressure within the population. Values can be - from 1.50 to 2.00; the latter is the default. - - - - - - - - Other Planner Options - - - - - default_statistics_target (integer) - - default_statistics_target configuration parameter - - - - 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. For more information - on the use of statistics by the PostgreSQL - query planner, refer to . - - - - - - constraint_exclusion (boolean) - - constraint exclusion - - - constraint_exclusion configuration parameter - - - - Enables or disables the query planner's use of table constraints to - limit table access. The default is off. - - - - When this parameter is on, the planner compares query - conditions with table CHECK constraints, and omits scanning tables - where the conditions contradict the constraints. (Presently - this is done only for child tables of inheritance scans.) For - example: - - -CREATE TABLE parent(key integer, ...); -CREATE TABLE child1000(check (key between 1000 and 1999)) INHERITS(parent); -CREATE TABLE child2000(check (key between 2000 and 2999)) INHERITS(parent); -... -SELECT * FROM parent WHERE key = 2400; - - - With constraint exclusion enabled, this SELECT will not scan - child1000 at all. This can improve performance when - inheritance is used to build partitioned tables. - - - - Currently, constraint_exclusion defaults to - off, because it risks incorrect results if - query plans are cached --- if a table constraint is changed or dropped, - the previously generated plan might now be wrong, and there is no - built-in mechanism to force re-planning. (This deficiency will - probably be addressed in a future - PostgreSQL release.) Another reason - for keeping it off is that the constraint checks are relatively - expensive, and in many circumstances will yield no savings. - It is recommended to turn this on only if you are actually using - partitioned tables designed to take advantage of the feature. - - - - - - from_collapse_limit (integer) - - from_collapse_limit configuration parameter - - - - 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 . - - - - - - join_collapse_limit (integer) - - join_collapse_limit configuration parameter - - - - The planner will rewrite explicit inner JOIN - constructs into lists of FROM items whenever a - list of no more than this many items in total would - result. Prior to PostgreSQL 7.4, joins - specified via the JOIN construct would - never be reordered by the query planner. The query planner has - subsequently been improved so that inner joins written in this - form can be reordered; this configuration parameter controls - the extent to which this reordering is performed. - - - At present, the order of outer joins specified via the - JOIN construct is never adjusted by the query - planner; therefore, join_collapse_limit has no - effect on this behavior. The planner may be improved to - reorder some classes of outer joins in a future release of - PostgreSQL. - - - - - - By default, this variable is set the same as - from_collapse_limit, which is appropriate - for most uses. Setting it to 1 prevents any reordering of - inner JOINs. Thus, the explicit join order - specified in the query will be the actual order in which the - relations are joined. The query planner does not always choose - the optimal join order; advanced users may elect to - temporarily set this variable to 1, and then specify the join - order they desire explicitly. Another consequence of setting - this variable to 1 is that the query planner will behave more - like the PostgreSQL 7.3 query - planner, which some users might find useful for backward - compatibility reasons. - - - - Setting this variable to a value between 1 and - from_collapse_limit might be useful to - trade off planning time against the quality of the chosen plan - (higher values produce better plans). - - - - - - - - - - Error Reporting and Logging - - - server log - - - - Where to log - - - where to log - - - - - - log_destination (string) - - log_destination configuration parameter - - - - PostgreSQL supports several methods - for logging server messages, including - stderr and - syslog. On Windows, - eventlog is also supported. Set this - option to a list of desired log destinations separated by - commas. The default is to log to stderr - only. - This option can only be set at server start or in the - postgresql.conf configuration file. - - - - - - redirect_stderr (boolean) - - redirect_stderr configuration parameter - - - - This option allows messages sent to stderr to be - captured and redirected into log files. - This option, in combination with logging to stderr, - is often more useful than - logging to syslog, since some types of messages - may not appear in syslog output (a common example - is dynamic-linker failure messages). - This option can only be set at server start. - - - - - - log_directory (string) - - log_directory configuration parameter - - - - When redirect_stderr is enabled, this option - determines the directory in which log files will be created. - It may be specified as an absolute path, or relative to the - cluster data directory. - This option can only be set at server start or in the - postgresql.conf configuration file. - - - - - - log_filename (string) - - log_filename configuration parameter - - - - When redirect_stderr is enabled, this option - sets the file names of the created log files. The value - is treated as a strftime pattern, - so %-escapes - can be used to specify time-varying file names. - If no %-escapes are present, - PostgreSQL will - append the epoch of the new log file's open time. For example, - if log_filename were server_log, then the - chosen file name would be server_log.1093827753 - for a log starting at Sun Aug 29 19:02:33 2004 MST. - This option can only be set at server start or in the - postgresql.conf configuration file. - - - - - - log_rotation_age (integer) - - log_rotation_age configuration parameter - - - - When redirect_stderr is enabled, this option - determines the maximum lifetime of an individual log file. - After this many minutes have elapsed, a new log file will - be created. Set to zero to disable time-based creation of - new log files. - This option can only be set at server start or in the - postgresql.conf configuration file. - - - - - - log_rotation_size (integer) - - log_rotation_size configuration parameter - - - - When redirect_stderr is enabled, this option - determines the maximum size of an individual log file. - After this many kilobytes have been emitted into a log file, - a new log file will be created. Set to zero to disable size-based - creation of new log files. - This option can only be set at server start or in the - postgresql.conf configuration file. - - - - - - log_truncate_on_rotation (boolean) - - log_truncate_on_rotation configuration parameter - - - - When redirect_stderr is enabled, this option will cause - PostgreSQL to truncate (overwrite), - rather than append to, any existing log file of the same name. - However, truncation will occur only when a new file is being opened - due to time-based rotation, not during server startup or size-based - rotation. When off, pre-existing files will be appended to in - all cases. For example, using this option in combination with - a log_filename like postgresql-%H.log - would result in generating twenty-four hourly log files and then - cyclically overwriting them. - This option can only be set at server start or in the - postgresql.conf configuration file. - - - Example: To keep 7 days of logs, one log file per day named - server_log.Mon, server_log.Tue, - etc, and automatically overwrite last week's log with this week's log, - set log_filename to server_log.%a, - log_truncate_on_rotation to on, and - log_rotation_age to 1440. - - - Example: To keep 24 hours of logs, one log file per hour, but - also rotate sooner if the log file size exceeds 1GB, set - log_filename to server_log.%H%M, - log_truncate_on_rotation to on, - log_rotation_age to 60, and - log_rotation_size to 1000000. - Including %M in log_filename allows - any size-driven rotations that may occur to select a filename - different from the hour's initial filename. - - - - - - syslog_facility (string) - - syslog_facility configuration parameter - - - - When logging to syslog is enabled, this option - determines the syslog - facility to be used. 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 daemon. - This option can only be set at server start. - - - - - - syslog_ident (string) - - syslog_identity configuration parameter - - - - When logging to syslog is enabled, this option - determines the program name used to identify - PostgreSQL messages in - syslog logs. The default is - postgres. - This option can only be set at server start. - - - - - - - - When To Log - - - - - client_min_messages (string) - - client_min_messages configuration parameter - - - - 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. - - - - - - log_min_messages (string) - - log_min_messages configuration parameter - - - - 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 change this setting. - - - - - - log_error_verbosity (string) - - log_error_verbosity configuration parameter - - - - 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. - Only superusers can change this setting. - - - - - - log_min_error_statement (string) - - log_min_error_statement configuration parameter - - - - 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 - higher 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 change this setting. - - - - - - log_min_duration_statement (integer) - - log_min_duration_statement configuration parameter - - - - Logs the statement and its duration on a single log line if its - duration is greater than or equal to the specified number of - milliseconds. Setting this to zero will print all statements - and their durations. Minus-one (the default) disables the - feature. 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. This setting is - independent of log_statement and - log_duration. Only superusers can change - this setting. - - - - - - silent_mode (boolean) - - silent_mode configuration parameter - - - - Runs the server silently. If this option is set, the server - will automatically run in background and any controlling - terminals are disassociated (same effect as - postmaster's option). - The server's standard output and standard error are redirected - to /dev/null, so any messages sent to them will be lost. - Unless syslog logging is selected or - redirect_stderr is enabled, using this option - is discouraged because it makes it impossible to see error messages. - - - - - - - - Here is a list of the various message severity levels used in - these settings: - - - DEBUG[1-5] - - - Provides information for use by developers. - - - - - - INFO - - - Provides information implicitly requested by the user, - e.g., during VACUUM VERBOSE. - - - - - - NOTICE - - - Provides information that may be helpful to users, e.g., - truncation of long identifiers and the creation of indexes as part - of primary keys. - - - - - - WARNING - - - Provides warnings to the user, e.g., COMMIT - outside a transaction block. - - - - - - ERROR - - - Reports an error that caused the current command to abort. - - - - - - LOG - - - Reports information of interest to administrators, e.g., - checkpoint activity. - - - - - - FATAL - - - Reports an error that caused the current session to abort. - - - - - - PANIC - - - Reports an error that caused all sessions to abort. - - - - - - - - - What To Log - - - - - debug_print_parse (boolean) - debug_print_rewritten (boolean) - debug_print_plan (boolean) - debug_pretty_print (boolean) - - debug_print_parse configuration parameter - - - debug_print_rewritten configuration parameter - - - debug_print_plan configuration parameter - - - debug_pretty_print configuration parameter - - - - These options enable various debugging output to be emitted. - 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 actually send this output - to the client or the server log, respectively. - These options are off by default. - - - - - - log_connections (boolean) - - log_connections configuration parameter - - - - This outputs a line to the server log 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. - - - - - - log_disconnections (boolean) - - log_disconnections configuration parameter - - - - This outputs a line in the server log similar to - log_connections but at session termination, - and includes the duration of the session. This is off by - default. This option can only be set at server start or in the - postgresql.conf configuration file. - - - - - - - log_duration (boolean) - - log_duration configuration parameter - - - - Causes the duration of every completed statement which satisfies - log_statement to be logged. When using this option, - if you are not using syslog, it is recommended - that you log the PID or session ID using log_line_prefix - so that you can link the statement to the - duration using the process ID or session ID. The default is - off. Only superusers can change this setting. - - - - - - log_line_prefix (string) - - log_line_prefix configuration parameter - - - - This is a printf-style string that is output at the - beginning of each log line. The default is an empty string. - Each recognized escape is replaced as outlined - below - anything else that looks like an escape is ignored. Other - characters are copied straight to the log line. Some escapes are - only recognised by session processes, and do not apply to - background processes such as the postmaster. Syslog - produces its own - time stamp and process ID information, so you probably do not want to - use those escapes if you are using syslog. - This option can only be set at server start or in the - postgresql.conf configuration file. - - - - - - Escape - Effect - Session only - - - - - %u - User name - yes - - - %d - Database name - yes - - - %r - Remote host name or IP address, and remote port - yes - - - %h - Remote Hostname or IP address - yes - - - %p - Process ID - no - - - %t - Time stamp (no milliseconds) - no - - - %m - Time stamp with milliseconds - no - - - %i - Command tag: This is the command that generated the log line. - yes - - - %c - Session ID: A unique identifier for each session. - It is 2 4-byte hexadecimal numbers (without leading zeros) - separated by a dot. The numbers - are the session start time and the process ID, so this can also - be used as a space saving way of printing these items. - yes - - - %l - Number of the log line for each process, starting at 1 - no - - - %s - Session start time stamp - yes - - - %x - Transaction ID - yes - - - %q - Does not produce any output, but tells non-session - processes to stop at this point in the string. Ignored by - session processes. - no - - - %% - Literal % - no - - - - - - - - - - log_statement (string) - - log_statement configuration parameter - - - - Controls which SQL statements are logged. Valid values are - none, ddl, mod, and - all. ddl logs all data definition - commands like CREATE, ALTER, and - DROP commands. mod logs all - ddl statements, plus INSERT, - UPDATE, DELETE, TRUNCATE, - and COPY FROM. PREPARE and - EXPLAIN ANALYZE statements are also logged if their - contained command is of an appropriate type. - - - The default is none. Only superusers can change this - setting. - - - - - The EXECUTE statement is not considered a - ddl or mod statement. When it is logged, - only the name of the prepared statement is reported, not the - actual prepared statement. - - - - When a function is defined in the - PL/pgSQLserver-side language, any queries - executed by the function will only be logged the first time that the - function is invoked in a particular session. This is because - PL/pgSQL keeps a cache of the - query plans produced for the SQL statements in the function. - - - - - - - log_hostname (boolean) - - log_hostname configuration parameter - - - - By default, connection log messages only show the IP address of the - connecting host. Turning on this option causes logging of the - host name as well. Note that depending on your host name resolution - setup this might impose a non-negligible performance penalty. This - option can only be set at server start or in the - postgresql.conf file. - - - - - - - - - - Runtime Statistics - - - Statistics Monitoring - - - - log_statement_stats (boolean) - log_parser_stats (boolean) - log_planner_stats (boolean) - log_executor_stats (boolean) - - log_statement_stats configuration parameter - - - log_parser_stats configuration parameter - - - log_planner_stats configuration parameter - - - log_executor_stats configuration parameter - - - - For each query, write performance statistics of the respective - module to the server log. This is a crude profiling - instrument. log_statement_stats reports total - statement statistics, while the others report per-module statistics. - log_statement_stats cannot be enabled together with - any of the per-module options. All of these options are disabled by - default. Only superusers can change these settings. - - - - - - - - - Query and Index Statistics Collector - - - - stats_start_collector (boolean) - - stats_start_collector configuration parameter - - - - 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. - - - - - - stats_command_string (boolean) - - stats_command_string configuration parameter - - - - 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 for more information. - - - - - - stats_block_level (boolean) - - stats_block_level configuration parameter - - - - Enables the collection of block-level statistics on database - activity. This option is disabled by default. If this option - is enabled, the data that is produced can be accessed via the - pg_stat and - pg_statio family of system views; - refer to for more information. - - - - - - stats_row_level (boolean) - - stats_row_level configuration parameter - - - - Enables the collection of row-level statistics on database - activity. This option is disabled by default. If this option - is enabled, the data that is produced can be accessed via the - pg_stat and - pg_statio family of system views; - refer to for more information. - - - - - - stats_reset_on_server_start (boolean) - - stats_reset_on_server_start configuration parameter - - - - If on, collected statistics are zeroed out whenever the server - is restarted. If off, statistics are accumulated across server - restarts. The default is off. This option can only - be set at server start. - - - - - - - - - - Automatic Vacuuming - - - Beginning in PostgreSQL 8.1, there is an optional server - process called the autovacuum daemon, whose purpose is - to automate the issuance of periodic VACUUM and - ANALYZE commands. When enabled, the autovacuum daemon - runs periodically and checks for tables that have had a large number - of updated or deleted tuples. This check uses the row-level statistics - collection facility; therefore, the autovacuum daemon cannot be used - unless and - are set TRUE. Also, it's - important to allow a slot for the autovacuum process when choosing - the value of . - - - - - - autovacuum (boolean) - - autovacuum configuration parameter - - - - Controls whether the server should start the - autovacuum subprocess. This is off by default. - This option can only be set at server start or in the - postgresql.conf file. - - - - - - autovacuum_naptime (integer) - - autovacuum_naptime configuration parameter - - - - Specifies the delay between activity rounds for the autovacuum - subprocess. In each round the subprocess examines one database - and issues VACUUM and ANALYZE commands - as needed for tables in that database. The delay is measured - in seconds, and the default is 60. - This option can only be set at server start or in the - postgresql.conf file. - - - - - - autovacuum_vacuum_threshold (integer) - - autovacuum_vacuum_threshold configuration parameter - - - - Specifies the minimum number of updated or deleted tuples needed - to trigger a VACUUM in any one table. - The default is 1000. - This option can only be set at server start or in the - postgresql.conf file. - - - - - - autovacuum_analyze_threshold (integer) - - autovacuum_analyze_threshold configuration parameter - - - - Specifies the minimum number of inserted, updated or deleted tuples - needed to trigger an ANALYZE in any one table. - The default is 500. - This option can only be set at server start or in the - postgresql.conf file. - - - - - - autovacuum_vacuum_scale_factor (floating point) - - autovacuum_vacuum_scale_factor configuration parameter - - - - Specifies a fraction of the table size to add to - autovacuum_vacuum_threshold - when deciding whether to trigger a VACUUM. - The default is 0.4. - This option can only be set at server start or in the - postgresql.conf file. - - - - - - autovacuum_analyze_scale_factor (floating point) - - autovacuum_analyze_scale_factor configuration parameter - - - - Specifies a fraction of the table size to add to - autovacuum_analyze_threshold - when deciding whether to trigger an ANALYZE. - The default is 0.2. - This option can only be set at server start or in the - postgresql.conf file. - - - - - - autovacuum_vacuum_cost_delay (integer) - - autovacuum_vacuum_cost_delay configuration parameter - - - - Specifies the cost delay value that will be used in automatic - VACUUM operations. If -1 is specified (which is the - default), the regular - value will be used. - This setting can be overridden for individual tables by entries in - pg_autovacuum. - - - - - - autovacuum_vacuum_cost_limit (integer) - - autovacuum_vacuum_cost_limit configuration parameter - - - - Specifies the cost limit value that will be used in automatic - VACUUM operations. If -1 is specified (which is the - default), the regular - value will be used. - This setting can be overridden for individual tables by entries in - pg_autovacuum. - - - - - - - - - Client Connection Defaults - - - Statement Behavior - - - - search_path (string) - - search_path configuration parameter - - pathfor schemas - - - 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 . - - - - - - default_tablespace (string) - - default_tablespace configuration parameter - - tablespacedefault - - - This variable specifies the default tablespace in which to create - objects (tables and indexes) when a CREATE command does - not explicitly specify a tablespace. - - - - The value is either the name of a tablespace, or an empty string - to specify using the default tablespace of the current database. - If the value does not match the name of any existing tablespace, - PostgreSQL will automatically use the default - tablespace of the current database. - - - - For more information on tablespaces, - see . - - - - - - check_function_bodies (boolean) - - check_function_bodies configuration parameter - - - - This parameter is normally on. When set to off, it - disables validation of the function body string during . Disabling validation is - occasionally useful to avoid problems such as forward references - when restoring function definitions from a dump. - - - - - - - transaction isolation level - - - default_transaction_isolation configuration parameter - - default_transaction_isolation (string) - - - Each SQL transaction has an isolation level, which can be - either read uncommitted, read - committed, repeatable read, or - serializable. This parameter controls the - default isolation level of each new transaction. The default - is read committed. - - - - Consult and for more information. - - - - - - - read-only transaction - - - default_transaction_read_only configuration parameter - - - default_transaction_read_only (boolean) - - - 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 off (read/write). - - - - Consult for more information. - - - - - - statement_timeout (integer) - - statement_timeout configuration parameter - - - - Abort any statement that takes over the specified number of - milliseconds. A value of zero (the default) turns off the limitation. - - - - - - - - Locale and Formatting - - - - - DateStyle (string) - - DateStyle configuration parameter - - - - 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 input/output specification for year/month/day ordering - (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 - for more information. The - default is ISO, MDY. - - - - - - timezone (string) - - timezone configuration parameter - - time zone - - - Sets the time zone for displaying and interpreting time - stamps. The default is 'unknown', which means to use whatever - the system environment specifies as the time zone. See for more information. - - - - - - australian_timezones (boolean) - - australian_timezones configuration parameter - - time zoneAustralian - - - If set to on, ACST, - CST, EST, and - SAT are interpreted as Australian time - zones rather than as North/South American time zones and - Saturday. The default is off. - - - - - - - significant digits - - - floating-point - display - - - extra_float_digits configuration parameter - - - extra_float_digits (integer) - - - 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. - - - - - - client_encoding (string) - - client_encoding configuration parameter - - character set - - - Sets the client-side encoding (character set). - The default is to use the database encoding. - - - - - - lc_messages (string) - - lc_messages configuration parameter - - - - Sets the language in which messages are displayed. Acceptable - values are system-dependent; see 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. - - - - - - lc_monetary (string) - - lc_monetary configuration parameter - - - - Sets the locale to use for formatting monetary amounts, for - example with the to_char family of - functions. Acceptable values are system-dependent; see 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. - - - - - - lc_numeric (string) - - lc_numeric configuration parameter - - - - Sets the locale to use for formatting numbers, for example - with the to_char family of - functions. Acceptable values are system-dependent; see 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. - - - - - - lc_time (string) - - lc_time configuration parameter - - - - 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 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. - - - - - - - - - Other Defaults - - - - - explain_pretty_print (boolean) - - explain_pretty_print configuration parameter - - - - Determines whether EXPLAIN VERBOSE uses the - indented or non-indented format for displaying detailed - query-tree dumps. The default is on. - - - - - - dynamic_library_path (string) - - dynamic_library_path configuration parameter - - dynamic loading - - - If a dynamically loadable module needs to be opened and the - file name specified in the CREATE FUNCTION or - LOAD command - does not have a directory component (i.e. the - name does not contain a slash), the system will search this - path for the required file. - - - - The value for dynamic_library_path has to be a - list of absolute directory paths separated by colons (or semi-colons - on Windows). If a list element starts - with the special string $libdir, the - compiled-in PostgreSQL package - library directory is substituted for $libdir. This - is where the modules provided by the standard - PostgreSQL distribution are installed. - (Use pg_config --pkglibdir to find out the name of - this directory.) For example: - -dynamic_library_path = '/usr/local/lib/postgresql:/home/my_project/lib:$libdir' - - or, in a Windows environment: - -dynamic_library_path = 'C:\tools\postgresql;H:\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. - - - - - - - - - - Lock Management - - - - - - deadlock - timeout during - - - timeout - deadlock - - - deadlock_timeout configuration parameter - - - 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. 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. - - - - - - max_locks_per_transaction (integer) - - max_locks_per_transaction configuration parameter - - - - The shared lock table is created with room to describe locks on - max_locks_per_transaction * - ( + - ) objects; - hence, no more than this many distinct objects can - be locked at any one time. (Thus, this parameter's name may be - confusing: it is not a hard limit on the number of locks taken - by any one transaction, but rather a maximum average value.) - 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. - - - - Increasing this parameter may cause PostgreSQL - to request more System V shared - memory than your operating system's default configuration - allows. See for information on how to - adjust those parameters, if necessary. - - - - - - - - - Version and Platform Compatibility - - - Previous PostgreSQL Versions - - - - add_missing_from (boolean) - FROMmissing - - add_missing_from configuration parameter - - - - When on, tables that are referenced by a query will be - automatically added to the FROM clause if not - already present. This behavior does not comply with the SQL - standard and many people dislike it because it can mask mistakes - (such as referencing a table where you should have referenced - its alias). The default is off. This variable can be - enabled for compatibility with releases of - PostgreSQL prior to 8.1, where this behavior was - allowed by default. - - - - Note that even when this variable is enabled, a warning - message will be emitted for each implicit FROM - entry referenced by a query. Users are encouraged to update - their applications to not rely on this behavior, by adding all - tables referenced by a query to the query's FROM - clause (or its USING clause in the case of - DELETE). - - - - - - regex_flavor (string) - regular expressions - - regex_flavor configuration parameter - - - - 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. See - for details. - - - - - - sql_inheritance (boolean) - - sql_inheritance configuration parameter - - inheritance - - - 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 for more information about - inheritance. - - - - - - default_with_oids (boolean) - - default_with_oids configuration parameter - - - - This controls whether CREATE TABLE and - CREATE TABLE AS include an OID column in - newly-created tables, if neither WITH OIDS - nor WITHOUT OIDS is specified. It also - determines whether OIDs will be included in tables created by - SELECT INTO. In PostgreSQL - 8.1 default_with_oids is disabled by default; in - prior versions of PostgreSQL, it was on by default. - - - - The use of OIDs in user tables is considered deprecated, so - most installations should leave this variable disabled. - Applications that require OIDs for a particular table should - specify WITH OIDS when creating the - table. This variable can be enabled for compatibility with old - applications that do not follow this behavior. - - - - - - escape_string_warning (boolean) - stringsescape - - escape_string_warning configuration parameter - - - - When on, a warning is issued if a backslash (\) - appears in an ordinary string literal ('...' - syntax). The default is off. - - - Escape string syntax (E'...') should be used for - escapes, because in future versions of - PostgreSQL ordinary strings will have - the standard-conforming behavior of treating backslashes - literally. - - - - - - - - Platform and Client Compatibility - - - - transform_null_equals (boolean) - IS NULL - - transform_null_equals configuration parameter - - - - When 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 SQL-spec-compliant 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 exact form = NULL, - 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 for related information. - - - - - - - - - - Preset Options - - - The following parameters are read-only, and are determined - when PostgreSQL is compiled or when it is - installed. As such, they have been excluded from the sample - postgresql.conf file. These options report - various aspects of PostgreSQL behavior - that may be of interest to certain applications, particularly - administrative front-ends. - - - - - - block_size (integer) - - block_size configuration parameter - - - - Reports the size of a disk block. It is determined by the value - of BLCKSZ when building the server. The default - value is 8192 bytes. The meaning of some configuration - variables (such as ) is - influenced by block_size. See for information. - - - - - - integer_datetimes (boolean) - - integer_datetimes configuration parameter - - - - Reports whether PostgreSQL was built - with support for 64-bit-integer dates and times. It is set by - configuring with --enable-integer-datetimes - when building PostgreSQL. The - default value is off. - - - - - - lc_collate (string) - - lc_collate configuration parameter - - - - Reports the locale in which sorting of textual data is done. - See for more information. - The value is determined when the database cluster is initialized. - - - - - - lc_ctype (string) - - lc_ctype configuration parameter - - - - Reports the locale that determines character classifications. - See for more information. - The value is determined when the database cluster is initialized. - Ordinarily this will be the same as lc_collate, - but for special applications it might be set differently. - - - - - - max_function_args (integer) - - max_function_args configuration parameter - - - - Reports the maximum number of function arguments. It is determined by - the value of FUNC_MAX_ARGS when building the server. The - default value is 100. - - - - - - max_identifier_length (integer) - - max_identifier_length configuration parameter - - - - Reports the maximum identifier length. It is determined as one - less than the value of NAMEDATALEN when building - the server. The default value of NAMEDATALEN is - 64; therefore the default - max_identifier_length is 63. - - - - - - max_index_keys (integer) - - max_index_keys configuration parameter - - - - Reports the maximum number of index keys. It is determined by - the value of INDEX_MAX_KEYS when building the server. The - default value is 32. - - - - - - server_encoding (string) - - server_encoding configuration parameter - - character set - - - Reports the database encoding (character set). - It is determined when the database is created. Ordinarily, - clients need only be concerned with the value of . - - - - - - server_version (string) - - server_version configuration parameter - - - - Reports the version number of the server. It is determined by the - value of PG_VERSION when building the server. - - - - - - standard_conforming_strings (boolean) - stringsescape - - standard_conforming_strings configuration parameter - - - - Reports whether ordinary string literals - ('...') treat backslashes literally, as specified in - the SQL standard. The value is currently always off, - indicating that backslashes are treated as escapes. It is planned - that this will change to on in a future - PostgreSQL release when string literal - syntax changes to meet the standard. Applications may check this - parameter to determine how string literals will be processed. - The presence of this parameter can also be taken as an indication - that the escape string syntax (E'...') is supported. - - - - - - - - - Customized Options - - - This feature was designed to allow options not normally known to - PostgreSQL to be added by add-on modules - (such as procedural languages). This allows add-on modules to be - configured in the standard ways. - - - - - - custom_variable_classes (string) - - custom_variable_classes configuration parameter - - - - This variable specifies one or several class names to be used for - custom variables, in the form of a comma-separated list. A custom - variable is a variable not normally known - to PostgreSQL proper but used by some - add-on module. Such variables must have names consisting of a class - name, a dot, and a variable name. custom_variable_classes - specifies all the class names in use in a particular installation. - This option can only be set at server start or in the - postgresql.conf configuration file. - - - - - - - - The difficulty with setting custom variables in - postgresql.conf is that the file must be read before add-on - modules have been loaded, and so custom variables would ordinarily be - rejected as unknown. When custom_variable_classes is set, - the server will accept definitions of arbitrary variables within each - specified class. These variables will be treated as placeholders and - will have no function until the module that defines them is loaded. When a - module for a specific class is loaded, it will add the proper variable - definitions for its class name, convert any placeholder - values according to those definitions, and issue warnings for any - placeholders of its class that remain (which presumably would be - misspelled configuration variables). - - - - Here is an example of what postgresql.conf might contain - when using custom variables: - - -custom_variable_classes = 'plr,plperl' -plr.path = '/usr/lib/R' -plperl.use_strict = true -plruby.use_strict = true # generates error: unknown class name - - - - - - Developer Options - - - 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. - - - - - debug_assertions (boolean) - - debug_assertions configuration parameter - - - - 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 - ). Note that - debug_assertions defaults to on - if PostgreSQL has been built with - assertions enabled. - - - - - - pre_auth_delay (integer) - - pre_auth_delay configuration parameter - - - - 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. - - - - - - trace_notify (boolean) - - trace_notify configuration parameter - - - - Generates a great amount of debugging output for the - LISTEN and NOTIFY - commands. or - must be - DEBUG1 or lower to send this output to the - client or server log, respectively. - - - - - - trace_locks (boolean) - trace_lwlocks (boolean) - trace_userlocks (boolean) - trace_lock_oidmin (boolean) - trace_lock_table (boolean) - debug_deadlocks (boolean) - log_btree_build_stats (boolean) - - - Various other code tracing and debugging options. - - - - - - wal_debug (boolean) - - wal_debug configuration parameter - - - - If on, emit WAL-related debugging output. This option is - only available if the WAL_DEBUG macro was - defined when PostgreSQL was - compiled. - - - - - - zero_damaged_pages (boolean) - - zero_damaged_pages configuration parameter - - - - Detection of a damaged page header normally causes - PostgreSQL to report an error, aborting the current - command. Setting zero_damaged_pages to on 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 on 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. - - - - - - - Short Options - - - For convenience there are also single letter command-line option switches - available for some parameters. They are described in . - - - - Short option key - - - - Short option - Equivalent - - - - - - - shared_buffers = x - - - - log_min_messages = DEBUGx - - - - fsync = off - - - - listen_addresses = x - - - - listen_addresses = '*' - - - - unix_socket_directory = x - - - - ssl = on - - - - max_connections = x - - - - port = x - - - - - , , , - , , - , - - For historical reasons, these options must be passed to - the individual server process via the - postmaster option, for example, - -$ postmaster -o '-S 1024 -s' - - or via PGOPTIONS from the client side, as - explained above. - - - - - enable_bitmapscan = off, - enable_hashjoin = off, - enable_indexscan = off, - enable_mergejoin = off, - enable_nestloop = off, - enable_seqscan = off, - enable_tidscan = off - - - - - - log_statement_stats = on - - - - - - work_mem = x - - - - , , - log_parser_stats = on, - log_planner_stats = on, - log_executor_stats = on - - - -
- -
-
- - Managing Kernel Resources