Permalink
category | subcategory | name | type | defaults | recommendation | range | context | docs | comments | |
---|---|---|---|---|---|---|---|---|---|---|
File Locations | config_file | string | ConfigDir/postgresql.conf | default | postmaster | Sets the server's main configuration file. | Can only be changed via command-line switch for obvious reasons. Useful primarily for testing different configuration options, or for automated restart with different configuration options. | |||
File Locations | data_directory | string | ConfigDir | default | postmaster | Sets the server's data directory. | Supports the ability to distribute files according to sysadmin or operating system defined schemes, or for launching multiple restart instances using the same binaries. Most of the time, it's better to use configuration options to define these locations so that all PostgreSQL binaries default to the correct paths. | |||
File Locations | external_pid_file | string | None | default | postmaster | Writes the postmaster PID to the specified file. | Creates an extra copy of the process ID. Used for server administration tools which need a copy of the process ID in a specific directory. | |||
File Locations | hba_file | string | ConfigDir/pg_hba.conf | default | postmaster | Sets the server's "hba" configuration file. | Allows you to move the pg_hba file to a sysadmin-specified location. | |||
File Locations | ident_file | string | ConfigDir/pg_ident.conf | default | postmaster | Sets the server's "ident" configuration file. | Allows you to move the pg_ident file to a sysadmin-specified location. | |||
Connections and Authentication | Security and Authentication | db_user_namespace | bool | off | do not use | sighup | Enables per-database user names. | This setting is a hack to work around the lack of per-database users in PostgreSQL. Unless you desperately need it, avoid this setting as it will eventually be replaced by something more maintainable. | ||
Connections and Authentication | Security and Authentication | krb_caseins_users | bool | off | varies | sighup | Sets whether Kerberos and GSSAPI user names should be treated as case-insensitive. | Speak with your sysadmin or network security about how to set the various kerberos settings to match your local kerberos setup. Kerberos support must be compiled in to PostgreSQL, and set in pg_hba.conf. | ||
Connections and Authentication | Security and Authentication | krb_server_keyfile | string | varies | sighup | Sets the location of the Kerberos server key file. | ||||
Connections and Authentication | Security and Authentication | password_encryption | bool | on | on | md5,scram-sha-256 | user | Encrypt passwords. | There is no good reason for this to be set to “off”. | |
Connections and Authentication | Security and Authentication | ssl | bool | off | on | sighup | Enables SSL connections. | One of several different settings to turn on SSL connections for PostgreSQL. SSL is a very good idea for highly secure setups. In addition, you must compile in SSL support and set SSL connections in pg_hba.conf, as well as configuring SSL itself. | ||
Connections and Authentication | Security and Authentication | ssl_ca_file | config | sighup | Location of the SSL certificate authority file. | You should always use SSL connections if you can. However, this does require setting up SSL. | ||||
Connections and Authentication | Security and Authentication | ssl_cert_file | server.crt | config | sighup | Location of the SSL server certificate file. | According to your SSL configuration, which maybe provided by your installer. | |||
Connections and Authentication | Security and Authentication | ssl_ciphers | string | HIGH:MEDIUM:+3DES:!aNULL | default | sighup | Sets the list of allowed SSL ciphers. | Allows DBAs to require “strong enough” or preset ciphers for SSL connections. If you have not compiled SSL support, this parameter will not be available. | ||
Connections and Authentication | Security and Authentication | ssl_crl_file | config | sighup | Location of the SSL certificate revocation list file. | According to your SSL configuration, which maybe provided by your installer. | ||||
Connections and Authentication | Security and Authentication | ssl_dh_params_file | config | sighup | Location of the SSL DH parameters file. | According to your SSL configuration, which maybe provided by your installer. | ||||
Connections and Authentication | Security and Authentication | ssl_ecdh_curve | prime256v1 | config | sighup | Sets the curve to use for ECDH. | According to your SSL configuration, which maybe provided by your installer. | |||
Connections and Authentication | Security and Authentication | ssl_key_file | server.key | config | sighup | Location of the SSL server private key file. | According to your SSL configuration, which maybe provided by your installer. | |||
Connections and Authentication | Security and Authentication | ssl_prefer_server_ciphers | on | config | sighup | Give priority to server ciphersuite order. | According to your SSL configuration, which maybe provided by your installer. | |||
Connections and Authentication | Connection Settings | bonjour | bool | off | off | postmaster | Enables advertising the server via Bonjour. | Set to “on” if you've compiled in Bonjour support and have an application which works by autodiscovery of Postgres. Otherwise, leave off. | ||
Connections and Authentication | Connection Settings | bonjour_name | string | machine name | default | postmaster | Sets the Bonjour service name. | Bonjour support must be compiled in and activated on the host machine to be live. You'll want alternate names if you have several instances of PostgreSQL on the same machine. | ||
Connections and Authentication | Connection Settings | listen_addresses | list | localhost | localhost,1 address | postmaster | Sets the host name or IP address(es) to listen to. | Set your listen_address as restrictively as possible; '*' should only be used for development machines | ||
Connections and Authentication | Connection Settings | max_connections | integer | 100 | under 1000 | 1 to 262143 | postmaster | Sets the maximum number of concurrent connections. | Should be set to the maximum number of connections which you expect to need at peak load. Note that each connection uses shared_buffer memory, as well as additional non-shared memory, so be careful not to run the system out of memory. In general, if you need more than 200 connections, you should probably be making more use of connection pooling. | |
Connections and Authentication | Connection Settings | port | integer | 5432 | default | 1 to 65535 | postmaster | Sets the TCP port the server listens on. | Alternate ports are primarily useful for running several versions, or instances, of PostgreSQL on one machine. However, if you're using an alternate port to support several versions, it's often better to compile in the port number. | |
Connections and Authentication | Connection Settings | superuser_reserved_connections | integer | 3 | default | 0 to 262143 | postmaster | Sets the number of connection slots reserved for superusers. | You should have at least one superuser connection open for troubleshooting at all times. So if you run more than two concurrent regular administrative tasks, you'll need more reserved connections. Note that this number is taken from max_connections, not in addition to it. | |
Connections and Authentication | Connection Settings | unix_socket_directories | string | /tmp | change | postmaster | Sets the directories where Unix-domain sockets will be created. | Change to a more secure directory, which many installers do for you. | ||
Connections and Authentication | Connection Settings | unix_socket_group | string | NULL | postgres | postmaster | Sets the owning group of the Unix-domain socket. | |||
Connections and Authentication | Connection Settings | unix_socket_permissions | integer | 777 | 770 | 0 to 511 | postmaster | Sets the access permissions of the Unix-domain socket. | ||
Connections and Authentication | Connection Persistence | authentication_timeout | time | 60 | decrease | 1s to 600s | sighup | Sets the maximum allowed time to complete client authentication. | For production databases, it's important that this value be synchronized with the timeout on the application server side. Most web applications will want a shorter timeout, like 20s. | |
Connections and Authentication | Connection Persistence | tcp_keepalives_count | integer | 0 | default | 0 to 2147483647 | user | Maximum number of TCP keepalive retransmits. | The three tcp_keepalive settings help manage a system which tends to have "undead" connection/query processes. For systems which support them, you can regulate checking that connections are still "live" end-to-end to kill them off. Not needed if you're not having a problem. Should be synchronized with the new TCP keepalive support in libpq on the client side. | |
Connections and Authentication | Connection Persistence | tcp_keepalives_idle | integer | 0 | default | 0s to 2147483647s | user | Time between issuing TCP keepalives. | ||
Connections and Authentication | Connection Persistence | tcp_keepalives_interval | integer | 0 | default | 0s to 2147483647s | user | Time between TCP keepalive retransmits. | ||
Resource Usage | CPU | max_parallel_workers | integer | 8 | cores/2 | 0 to 1024 | user | Sets the maximum number of parallel workers than can be active at one time. | … if you think you can benefit from parallel query, and even cores/1 for DW systems. | |
Resource Usage | CPU | max_worker_processes | integer | 8 | increase | 0 to 262143 | postmaster | Maximum number of concurrent worker processes. | Increase to max_parallel_workers + other workers, such as workers for logical replication and custom background workers. Not more than your number of cores, though. | |
Resource Usage | Memory | dynamic_shared_memory_type | ENUM | auto-detect | default | posix,sysv,mmap,none | postmaster | Selects the dynamic shared memory implementation used. | ||
Resource Usage | Memory | huge_pages | ENUM | try | default | off,on,try | postmaster | Use of huge pages on Linux. | However, for small systems (< 2GB of RAM) may be beneficial to set to “off”. | |
Resource Usage | Memory | max_prepared_transactions | integer | 5 | 0 or max_connections | 0 to 262143 | postmaster | Sets the maximum number of simultaneously prepared transactions. | Most applications do not use XA prepared transactions, so should set this parameter to 0. If you do require prepared transactions, you should set this equal to max_connections to avoid blocking. May require increasing kernel memory parameters. | |
Resource Usage | Memory | shared_buffers | memory | varies 512kB to 8MB | AvRAM / 4 | 168kB to 10737418238kB | postmaster | Sets the number of shared memory buffers used by the server. | A memory quantity defining PostgreSQL's "dedicated" RAM, which is used for connection control, active operations, and more. However, since PostgreSQL also needs free RAM for file system buffers, sorts and maintenance operations, it is not advisable to set shared_buffers to a majority of RAM. Note that increasing shared_buffers often requires you to increase some system kernel parameters, most notably SHMMAX and SHMALL. See Operating System Environment: Managing Kernel Resources in the PostgreSQL documentation for more details. Also note that shared_buffers over 2GB is only supported on 64-bit systems. | |
Resource Usage | Memory | temp_buffers | memory | 8MB | default | 1008kB to 10737418238kB | user | Sets the maximum number of temporary buffers used by each session. | Currently used only for holding temporary tables in memory. If your application requires heavy use of temporary tables (many proprietary reporting engines do) then you might want to increase this substantially. However, be careful because this is non-shared RAM which is allocated per session. Otherwise, the default is fine. | |
Resource Usage | Memory | work_mem | integer | 1MB | ( AvRAM / max_connections ) OR ( AvRAM / 2 * max_connections ) | 64kB to 2147483647kB | user | Sets the maximum memory to be used for query workspaces. | Sets the limit for the amount of non-shared RAM available for each query operation, including sorts and hashes. This limit acts as a primitive resource control, preventing the server from going into swap due to overallocation. Note that this is non-shared RAM per operation, which means large complex queries can use multple times this amount. Also, work_mem is allocated by powers of two, so round to the nearest binary step. The second formula is for reporting and DW servers which run a lot of complex queries. | |
Resource Usage | Kernel Resources | max_files_per_process | integer | 1000 | default | 25 to 2147483647 | postmaster | Sets the maximum number of simultaneously open files for each server process. | If you have a large database with many partitioned tables, you may want to increase this. Note that you will probably have to increase ulimits for the postgres user or system as well. | |
Resource Usage | Kernel Resources | max_stack_depth | memory | 2MB | default | 100kB to 2147483647kB | superuser | Sets the maximum stack depth, in kilobytes. | Increase this if you have experienced the relevant error. | |
Resource Usage | Kernel Resources | shared_preload_libraries | string | default | postmaster | Lists shared libraries to preload into server. | Primarily used for custom C libraries (data types, stored procedures) which you expect your application to use heavily. Trades memory overhead for these libraries against load time, so really should only be used for libraries you expect most queries to require. | |||
Resource Usage | Disk | temp_file_limit | memory | -1 (disabled) | 10GB | -1kB to 2147483647kB | superuser | Limits the total size of all temporary files used by each process. | … or something which is bigger than your largest possible sort, but not big enough to run you out of disk space. | |
WAL and Checkpoints | Settings | max_wal_size | memory | 1GB | default | 2MB to 2147483647MB | sighup | Sets the WAL size that triggers a checkpoint. | … except for databases that write more than 1GB/hour of data, in which case increase the size of the log so that it's at least an hour worth of logs | |
WAL and Checkpoints | Settings | min_wal_size | memory | 80MB | default | 2MB to 2147483647MB | sighup | Sets the minimum size to shrink the WAL to. | ||
WAL and Checkpoints | Settings | wal_compression | bool | off | on | superuser | Compresses full-page writes written in WAL file. | … unless your storage is less constrained than your CPU. | ||
WAL and Checkpoints | Settings | wal_log_hints | off | off | postmaster | Writes full pages to WAL when first modified after a checkpoint, even for a non-critical modifications. | ||||
WAL and Checkpoints | Archiving | archive_command | string | (disabled) | varies | sighup | Sets the shell command that will be called to archive a WAL file. | All of the Archiving settings are part of a Point In Time Recovery or Warm Standby configuration. Please see the Backup and Restore section for more information. | ||
WAL and Checkpoints | Archiving | archive_mode | bool | off | varies | always,on,off | postmaster | Allows archiving of WAL files using archive_command. | Requires a restart to change, so if you want to turn archiving on and off, set this to 'on' and change archive_command instead. Even better, set archive_command to a script which can be disabled by trigger or ENV variable. | |
WAL and Checkpoints | Archiving | archive_timeout | integer | 0 | varies | 0s to 1073741823s | sighup | Forces a switch to the next WAL file if a new file has not been started within N seconds. | Dependant on your tradeoff between disk space and letting the standby get behind. | |
WAL and Checkpoints | Memory | wal_buffers | memory | -1 auto | default | -18kB to 2621438kB | postmaster | Sets the number of disk-page buffers in shared memory for WAL. | On very busy, high-core machines it can be useful to raise this to as much as 128MB. | |
WAL and Checkpoints | Synch to Disk | backend_flush_after | memory | 0 | default | 08kB to 2568kB | user | Number of pages after which previously performed writes are flushed to disk. | Unless you have time to tune memory flushing behavior and test for improvements/regressions | |
WAL and Checkpoints | Synch to Disk | fsync | bool | on | on | sighup | Forces synchronization of updates to disk. | Never turn off unless your data is entirely disposable. Setting fsync=off is the equivalent of saying “I don't care about my data, I can recreate the database from scratch if I have to.” If synch activity is a performance concern, see synchronous_commit. | ||
WAL and Checkpoints | Synch to Disk | full_page_writes | bool | on | on | sighup | Writes full pages to WAL when first modified after a checkpoint. | This is PostgreSQL's triple-check on transaction log integrity. Leave it on unless you have enough in-depth knowledge of your filesystem and hardware to be certain that torn page writes of log segments are completely prevented. Solaris/ZFS users claim to be able to turn this off, but that has not been destruction-tested. | ||
WAL and Checkpoints | Synch to Disk | synchronous_commit | bool | on | on | local,remote_write,remote_apply,on,off | user | Sets the current transaction's synchronization level. | If data integrity is less important to you than response times (for example, if you are running a social networking application or processing logs) you can turn this off, making your transaction logs asynchronous. This can result in up to wal_buffers or wal_writer_delay * 2 worth of data in an unexpected shutdown, but your database will not be corrupted. Note that you can also set this on a per-session basis, allowing you to mix “lossy” and “safe” transactions, which is a better approach for most applications. | |
WAL and Checkpoints | Synch to Disk | wal_sync_method | string | OS-dependent | default | fsync,fdatasync,open_sync,open_datasync | sighup | Selects the method used for forcing WAL updates to disk. | On install, PostgreSQL figures out the best method for your OS. It's pretty good at this point; don't change the default. Note that the value of "fsync" shown in your postgresql.conf file is not necessarily the setting the server is using; try SHOW instead. | |
WAL and Checkpoints | Synch to Disk | wal_writer_delay | integer | 200 | default | 1ms to 10000ms | sighup | Time between WAL flushes performed in the WAL writer. | Defines the maximum data (in time) that can be lost if synchronous_commit=off and the database shuts down. Because of long transactions, actual data lost can be up to twice this time. Has no effect if synchronous_commit=on. If you are going to turn synchronous_commit=off server-wide, you should probably lower this to prevent too much data loss. | |
WAL and Checkpoints | Synch to Disk | wal_writer_flush_after | memory | 1MB | default | 08kB to 21474836478kB | sighup | Amount of WAL written out by WAL writer that triggers a flush. | ||
WAL and Checkpoints | Commit Settings | commit_delay | integer | 0 | 0 | 0 to 100000 | superuser | Sets the delay in microseconds between transaction commit and flushing WAL to disk. | A primitive form of group commit without asynchronicity. Performance testing of this is very mixed; only set to non-zero if you have time to test the specific performance impact on your workload. Reasonable values are 200 to 1000. | |
WAL and Checkpoints | Commit Settings | commit_siblings | integer | 5 | 1 | 0 to 1000 | user | Sets the minimum concurrent open transactions before performing commit_delay. | See commit_delay. Reasonable values are 3 to 8 | |
WAL and Checkpoints | Checkpoints | checkpoint_completion_target | real | 1 | default | 0 to 1 | sighup | Time spent flushing dirty buffers during checkpoint, as fraction of checkpoint interval. | Defines the fraction of one checkpoint_interval over which to spread checkpoints. The default value works for most users. | |
WAL and Checkpoints | Checkpoints | checkpoint_flush_after | memory | 256kB | default | 08kB to 2568kB | sighup | Number of pages after which previously performed writes are flushed to disk. | Unless you have time to tune memory flushing behavior and test for improvements/regressions | |
WAL and Checkpoints | Checkpoints | checkpoint_timeout | integer | 300 | default | 30s to 86400s | sighup | Sets the maximum time between automatic WAL checkpoints. | If you do really large ETL batches, you may want to increase this setting to the maximum length of a batch run. | |
WAL and Checkpoints | Checkpoints | checkpoint_warning | integer | 30 | default | 0s to 2147483647s | sighup | Enables warnings if checkpoint segments are filled more frequently than this. | ||
WAL and Checkpoints | Background Writer | bgwriter_delay | time | 200 | default | 10ms to 10000ms | sighup | Background writer sleep time between rounds. | Thanks to bgwriter autotuning, it should no longer be necessary for most users to touch the bgwriter settings. Only modify these if you have a demonstrated issue shown by checkpoint spikes and monitoring pg_stat_bgwriter. Laptop PostgreSQL users may want to increase bgwriter_delay to 60s to decrease I/O activity, since it is no longer possible to turn the bgwriter off. | |
WAL and Checkpoints | Background Writer | bgwriter_flush_after | memory | 512kB | default | 08kB to 2568kB | sighup | Number of pages after which previously performed writes are flushed to disk. | Unless you have time to tune memory flushing behavior and test for improvements/regressions | |
WAL and Checkpoints | Background Writer | bgwriter_lru_maxpages | integer | 100 | default | 0 to 1073741823 | sighup | Background writer maximum number of LRU pages to flush per round. | ||
WAL and Checkpoints | Background Writer | bgwriter_lru_multiplier | real | 2 | default | 0 to 10 | sighup | Multiple of the average buffer usage to free per round. | ||
Replication | Master Options | max_replication_slots | integer | 10 | max replicas * 2 | 0 to 262143 | postmaster | Sets the maximum number of simultaneously defined replication slots. | Set to twice as many replicas as you ever expect to have. | |
Replication | Master Options | max_wal_senders | integer | 10 | Max replicas you expect to have, doubled | 0 to 262143 | postmaster | Sets the maximum number of simultaneously running WAL sender processes. | If you are replicating, you want to set this to the maximum number of standby servers you might possibly have. Performance impact when set above zero, but no additional penalty for setting it higher. | |
Replication | Master Options | synchronous_standby_names | string | NULL | default | sighup | Number of synchronous standbys and list of names of potential synchronous ones. | Special, see syntax for sync standby config. Don't get into this if you're not sure what you're doing. | ||
Replication | Master Options | track_commit_timestamp | bool | off | on | postmaster | Collects transaction commit time. | |||
Replication | Master Options | vacuum_defer_cleanup_age | integer | 0 | 0 | 0 to 1000000 | sighup | Number of transactions by which VACUUM and HOT cleanup should be deferred, if any. | No longer effective thanks to hot_standby_feedback. | |
Replication | Master Options | wal_keep_segments | integer | 0 | 8 to 128 | 0 to 2147483647 | sighup | Sets the number of WAL files held for standby servers. | … if using replication. Minimum number of WAL log segments to keep in order to support re-synchronizing streaming standby servers which have fallen behind or for an initial sync, a good rule of thumb is 4, or however many segments you go through in 30s, whichever is higher. This is in addition to max_wal_size, so make sure you have enough disk space. Not required if you are archiving logs. | |
Replication | Master Options | wal_level | enum | replica | replica or logical | minimal,replica,logical | postmaster | Set the level of information written to the WAL. | Level replica is required for binary replication, and level logical is required for logical replication. This is a setting because raising the level adds more writes to the WAL, so if you’re not doing replication or archiving at all, set it to minimal. | |
Replication | Master Options | wal_sender_timeout | time | 60sec | default | 0ms to 2147483647ms | sighup | Sets the maximum time to wait for WAL replication. | ||
Replication | Standby Options | hot_standby | bool | on | on | postmaster | Allows connections and queries during recovery. | Set to “on”, unless you want to specifically prohibit people from running queries on a standby server. | ||
Replication | Standby Options | hot_standby_feedback | bool | off | on | sighup | Allows feedback from a hot standby to the primary that will avoid query conflicts. | Helps avoid query cancel on the replicas in most cases. Turn it off for a replica which does long-running reports and is allowed to lag. | ||
Replication | Standby Options | max_logical_replication_workers | integer | 4 | default | 0 to 262143 | postmaster | Maximum number of logical replication worker processes. | … unless logical replication is falling behind and the replica isn't handling other traffic | |
Replication | Standby Options | max_standby_archive_delay | integer | 30000 | -1ms to 2147483647ms | sighup | Sets the maximum delay before canceling queries when a hot standby server is processing archived WAL data. | If you are replicating primarily for failover, set this to a very low value (like 0) in order to keep the standby as up to date as possible. If this standby is running queries as its primary role, set to the length of time of the longest-running query you want to allow. | ||
Replication | Standby Options | max_standby_streaming_delay | integer | 30000 | -1ms to 2147483647ms | sighup | Sets the maximum delay before canceling queries when a hot standby server is processing streamed WAL data. | If you are replicating primarily for failover, set this to a very low value (like 0) in order to keep the standby as up to date as possible. If this standby is running queries as its primary role, set to the length of time of the longest-running query you want to allow. | ||
Replication | Standby Options | max_sync_workers_per_subscription | integer | 2 | default | 0 to 262143 | sighup | Maximum number of table synchronization workers per subscription. | Consider raising to cores/2 when initially synchronizing logical replication for a new replica. | |
Replication | Standby Options | wal_receiver_status_interval | time | 10sec | default | 0s to 2147483s | sighup | Sets the maximum interval between WAL receiver status reports to the primary. | ||
Replication | Standby Options | wal_receiver_timeout | time | 60sec | default | 0ms to 2147483647ms | sighup | Sets the maximum wait time to receive data from the primary. | ||
Replication | Standby Options | wal_retrieve_retry_interval | time | 5sec | default | 1ms to 2147483647ms | sighup | Sets the time to wait before retrying to retrieve WAL after a failed attempt. | ||
Query Tuning | Planner Cost Constants | cpu_index_tuple_cost | real | 0.005 | 0.001 | 0 to 1.79769e+308 | user | Sets the planner's estimate of the cost of processing each index entry during an index scan. | Decrease this slightly to make your database favor indexes slightly more. | |
Query Tuning | Planner Cost Constants | cpu_operator_cost | real | 0.0025 | 0.0005 | 0 to 1.79769e+308 | user | Sets the planner's estimate of the cost of processing each operator or function call. | Decrease this slightly to make your database favor indexes slightly more. | |
Query Tuning | Planner Cost Constants | cpu_tuple_cost | real | 0.01 | default | 0 to 1.79769e+308 | user | Sets the planner's estimate of the cost of processing each tuple (row). | ||
Query Tuning | Planner Cost Constants | effective_cache_size | integer | 65536 | ( AvRAM * 0.75 ) | 18kB to 21474836478kB | user | Sets the planner's assumption about the size of the disk cache. | Tells the PostgreSQL query planner how much RAM is estimated to be available for caching data, in both shared_buffers and in the filesystem cache. This setting just helps the planner make good cost estimates; it does not actually allocate the memory. | |
Query Tuning | Planner Cost Constants | random_page_cost | real | 4 | default | 0 to 1.79769e+308 | user | Sets the planner's estimate of the cost of a nonsequentially fetched disk page. | Sets the ratio of seek to scan time for your database storage. Should not be altered unless you're using special storage (SSDs, high end SANs, etc.) where seek/scan ratios are actually different. If you need the database to favor indexes more, tune effective_cache_size and some of the cpu_* costs instead. | |
Query Tuning | Planner Cost Constants | seq_page_cost | real | 1 | default | 0 to 1.79769e+308 | user | Sets the planner's estimate of the cost of a sequentially fetched disk page. | The main reason to modify seq_page_cost is to try to get planner costs to more-or-less indicate execution times in milleseconds. All other costs change relative to this cost automatically. | |
Query Tuning | Planner Method Configuration | enable_bitmapscan | bool | on | default | user | Enables the planner's use of bitmap-scan plans. | For interactive session use only when troubleshooting queries. | ||
Query Tuning | Planner Method Configuration | enable_gathermerge | bool | on | default | user | Enables the planner's use of gather merge plans. | |||
Query Tuning | Planner Method Configuration | enable_hashagg | bool | on | default | user | Enables the planner's use of hashed aggregation plans. | For interactive session use only when troubleshooting queries. | ||
Query Tuning | Planner Method Configuration | enable_hashjoin | bool | on | default | user | Enables the planner's use of hash join plans. | For interactive session use only when troubleshooting queries. | ||
Query Tuning | Planner Method Configuration | enable_indexonlyscan | bool | on | default | user | Enables the planner's use of index-only-scan plans. | |||
Query Tuning | Planner Method Configuration | enable_indexscan | bool | on | default | user | Enables the planner's use of index-scan plans. | For interactive session use only when troubleshooting queries. | ||
Query Tuning | Planner Method Configuration | enable_material | bool | on | default | user | Enables the planner's use of materialization. | For interactive session use only when troubleshooting queries. | ||
Query Tuning | Planner Method Configuration | enable_mergejoin | bool | on | default | user | Enables the planner's use of merge join plans. | For interactive session use only when troubleshooting queries. | ||
Query Tuning | Planner Method Configuration | enable_nestloop | bool | on | default | user | Enables the planner's use of nested-loop join plans. | For interactive session use only when troubleshooting queries. | ||
Query Tuning | Planner Method Configuration | enable_seqscan | bool | on | default | user | Enables the planner's use of sequential-scan plans. | For interactive session use only when troubleshooting queries. | ||
Query Tuning | Planner Method Configuration | enable_sort | bool | on | default | user | Enables the planner's use of explicit sort steps. | For interactive session use only when troubleshooting queries. | ||
Query Tuning | Planner Method Configuration | enable_tidscan | bool | on | default | user | Enables the planner's use of TID scan plans. | For interactive session use only when troubleshooting queries. | ||
Query Tuning | Genetic Query Optimizer | geqo | bool | on | default | user | Enables genetic query optimization. | |||
Query Tuning | Genetic Query Optimizer | geqo_effort | integer | 5 | default | 1 to 10 | user | GEQO: effort is used to set the default for other GEQO parameters. | ||
Query Tuning | Genetic Query Optimizer | geqo_generations | integer | 0 | default | 0 to 2147483647 | user | GEQO: number of iterations of the algorithm. | ||
Query Tuning | Genetic Query Optimizer | geqo_pool_size | integer | 0 | default | 0 to 2147483647 | user | GEQO: number of individuals in the population. | ||
Query Tuning | Genetic Query Optimizer | geqo_seed | real | 0 | 0 to 1 | user | GEQO: seed for random path selection. | If you set this manually, you can force repeatable execution paths for GEQO queries. | ||
Query Tuning | Genetic Query Optimizer | geqo_selection_bias | real | 2 | default | 1.5 to 2 | user | GEQO: selective pressure within the population. | ||
Query Tuning | Genetic Query Optimizer | geqo_threshold | integer | 12 | 15 | 2 to 2147483647 | user | Sets the threshold of FROM items beyond which GEQO is used. | With new, faster processors it's tempting to raise the geqo_threshold a little, such as to 16 or 18. Increasing more than that is unwise as query planning time goes up geometrically. | |
Query Tuning | Parallel Query | force_parallel_mode | ENUM | off | default | off,on,regress | user | Forces use of parallel query facilities. | ||
Query Tuning | Parallel Query | max_parallel_workers_per_gather | integer | 2 | increase | 0 to 1024 | user | Sets the maximum number of parallel processes per executor node. | Increase if you plan to use parallel query to 4 or 8, depending on cores/concurrent sessions. | |
Query Tuning | Parallel Query | min_parallel_index_scan_size | memory | 512kB | default | 08kB to 7158278828kB | user | Sets the minimum amount of index data for a parallel scan. | ||
Query Tuning | Parallel Query | min_parallel_table_scan_size | memory | 8MB | default | 08kB to 7158278828kB | user | Sets the minimum amount of table data for a parallel scan. | … , unless doing IoT or a read-only database. Raise to 100MB or so if your traffic on the database is very bursty, to prevent the WAL from shrinking too much. | |
Query Tuning | Parallel Query | parallel_setup_cost | real | 1000 | default | 0 to 1.79769e+308 | user | Sets the planner's estimate of the cost of starting up worker processes for parallel query. | ||
Query Tuning | Parallel Query | parallel_tuple_cost | real | 0.1 | default | 0 to 1.79769e+308 | user | Sets the planner's estimate of the cost of passing each tuple (row) from worker to master backend. | ||
Query Tuning | Other Planner Options | constraint_exclusion | bool | partiton | default | partition,on,off | user | Enables the planner to use constraints to optimize queries. | Default of “partition” is fine for most users. Setting it to “on” can allow optimization of UNION queries as well, but deserves testing before production deployment. | |
Query Tuning | Other Planner Options | cursor_tuple_fraction | real | 0 | 0 to 1 | user | Sets the planner's estimate of the fraction of a cursor's rows that will be retrieved. | Increase this to 0.9 if most of the time you're using cursors to step through all of the rows of a query result. | ||
Query Tuning | Other Planner Options | default_statistics_target | integer | 100 | varies | 1 to 10000 | user | Sets the default statistics target. | Most applications can use the default of 100. For very small/simple databases, decrease to 10 or 50. Data warehousing applications generally need to use 500 to 1000. Otherwise, increase statistics targets on a per-column basis. | |
Query Tuning | Other Planner Options | effective_io_concurrency | integer | 1 | varies | 0 to 1000 | user | Number of simultaneous requests that can be handled efficiently by the disk subsystem. | Set to the number of disks in your RAID array or number of I/O channels. Available only for platforms with posix_fadvise support (i.e. Linux). Currently only affects the execution of parallel bitmapscan, but might affect other I/O operations in future versions. | |
Query Tuning | Other Planner Options | from_collapse_limit | integer | 8 | default | 1 to 2147483647 | user | Sets the FROM-list size beyond which subqueries are not collapsed. | While it's probably true that newer CPUs could support higher collapse_limits, there's not much incremental benefit to just raising either collapse_limit to 10 or 11. | |
Query Tuning | Other Planner Options | join_collapse_limit | integer | 8 | default | 1 to 2147483647 | user | Sets the FROM-list size beyond which JOIN constructs are not flattened. | If for some reason you wanted to explicitly declare the join order for all of your queries, you could set this to 1. That is not recommended, though. | |
Query Tuning | Other Planner Options | replacement_sort_tuples | integer | 150000 | 0 | 0 to 2147483647 | user | Sets the maximum number of tuples to be sorted using replacement selection. | Disable, this setting will be removed from Postgres 11. | |
Statistics | Monitoring | log_executor_stats | bool | off | default | superuser | Writes executor performance statistics to the server log. | Used for profiling the query executor. | ||
Statistics | Monitoring | log_parser_stats | bool | off | default | superuser | Writes parser performance statistics to the server log. | Used for profiling the query parser. | ||
Statistics | Monitoring | log_planner_stats | bool | off | default | superuser | Writes planner performance statistics to the server log. | Used for profiling the query planner. | ||
Statistics | Monitoring | log_statement_stats | bool | off | default | superuser | Writes cumulative performance statistics to the server log. | Used for full query path profiling. Exclusive of the other three options. | ||
Statistics | Query and Index Statistics Collector | stats_temp_directory | string | pg_stat_tmp | default | sighup | Writes temporary statistics files to the specified directory. | Useful for extremely high-volume databases; the stats temp directory could be set to a RAMdisk or other high-speed resource (at the cost of potentially losing some stats) as this file gets updated hundreds of times per second. | ||
Statistics | Query and Index Statistics Collector | track_activities | bool | on | default | superuser | Collects information about executing commands. | |||
Statistics | Query and Index Statistics Collector | track_activity_query_size | integer | 1024 | default | 100 to 102400 | postmaster | Sets the size reserved for pg_stat_activity.query, in bytes. | Sets the truncation threshold of queries in pg_stat_activity (and pg_stat_statements). Increase it if you have really long queries which are being cut off, but there is significant extra memory usage for keeping longer queries. | |
Statistics | Query and Index Statistics Collector | track_counts | bool | on | default | superuser | Collects statistics on database activity. | Needed for autovacuum to work properly. Do not turn off. | ||
Statistics | Query and Index Statistics Collector | track_functions | enum | None | pl | none,pl,all | superuser | Collects function-level statistics on database activity. | Set it to 'pl' to collect stats on user-defined functions. Very useful for stored procedure performance profiling and troubleshooting. | |
Statistics | Query and Index Statistics Collector | track_io_timing | bool | off | default | superuser | Collects timing statistics for database I/O activity. | Turn it on if you're monitoring disk usage per request. | ||
Statistics | Query and Index Statistics Collector | update_process_title | bool | on | default | superuser | Updates the process title to show the active SQL command. | Updates the process title on OSes which support this. Very useful for checking resource usage by currently running queries. | ||
Maintenance | Memory | maintenance_work_mem | integer | 16MB | ( AvRAM / 8 ) for most | 1024kB to 2147483647kB | user | Sets the maximum memory to be used for maintenance operations. | Sets the limit for the amount that autovacuum, manual vacuum, bulk index build and other maintenance routines are permitted to use. Setting it to a moderately high value will increase the efficiency of vacuum and other operations. Applications which perform large ETL operations may need to allocate up to 1/4 of RAM to support large bulk vacuums. Note that each autovacuum worker may use this much, so if using multiple autovacuum workers you may want to decrease this value so that they can't claim over 1/8 or 1/4 of available RAM. | |
Maintenance | Manual Vacuum | vacuum_cost_delay | integer | 0 | 0ms to 100ms | user | Vacuum cost delay in milliseconds. | Most of the time, you will want manual vacuum to execute without vacuum_delay, especially if you're using it as part of ETL. If for some reason you can't use autovacuum on an OLTP database, however, you may want to increase this to 20ms to decrease the impact vacuum has on currently running queries. Will cause vacuum to take up to twice as long to complete. | ||
Maintenance | Manual Vacuum | vacuum_cost_limit | integer | 200 | default | 1 to 10000 | user | Vacuum cost amount available before napping. | ||
Maintenance | Manual Vacuum | vacuum_cost_page_dirty | integer | 20 | default | 0 to 10000 | user | Vacuum cost for a page dirtied by vacuum. | ||
Maintenance | Manual Vacuum | vacuum_cost_page_hit | integer | 1 | default | 0 to 10000 | user | Vacuum cost for a page found in the buffer cache. | ||
Maintenance | Manual Vacuum | vacuum_cost_page_miss | integer | 10 | default | 0 to 10000 | user | Vacuum cost for a page not found in the buffer cache. | ||
Maintenance | Manual Vacuum | vacuum_freeze_min_age | integer | 50000000 | lower, varies | 0 to 1000000000 | user | Minimum age at which VACUUM should freeze a table row. | Most users will want to decrease this so that rows which have been cold for a long time get frozen earlier, and avoid an autovacuum_freeze. The suggestion of 500000 is for a moderately busy database; do not set to less than a few hours worth of XIDs. Maximum setting is 1/2 of autovaccuum_max_freeze_age. | |
Maintenance | Manual Vacuum | vacuum_freeze_table_age | integer | 150000000 | 400000000 | 0 to 2000000000 | user | Age at which VACUUM should scan whole table to freeze tuples. | Generally set to 80% of autovacuum_max_freeze age to preempt a full vacuum freeze. If you can schedule cron vacuums during application slow periods, it might be valuable to lower this value in order to encourage vacuum freezing of tables before they are triggered by autovacuum. | |
Maintenance | Manual Vacuum | vacuum_multixact_freeze_min_age | integer | 5000000 | lower, varies | 0 to 1000000000 | user | Minimum age at which VACUUM should freeze a MultiXactId in a table row. | Like freeze_min_age, lower this to somewhere around an hour of XID burn. Try starting with 500000. | |
Maintenance | Manual Vacuum | vacuum_multixact_freeze_table_age | integer | 150000000 | 350000000 | 0 to 2000000000 | user | Multixact age at which VACUUM should scan whole table to freeze tuples. | Set to 80% of autovaccum_multixact_freeze_max_age | |
Maintenance | Autovacuum | autovacuum | bool | on | on | sighup | Starts the autovacuum subprocess. | Starts the daemon which cleans up your tables and indexes, preventing bloat and poor response times. The only reason to set it to “off” is for databases which regularly do large batch operations like ETL. Note that you can adjust the frequency or stop autovacuum on individual tables by adding rows to the pg_autovacuum system table. | ||
Maintenance | Autovacuum | autovacuum_analyze_scale_factor | real | 0.1 | default | 0 to 100 | sighup | Number of tuple inserts, updates, or deletes prior to analyze as a fraction of reltuples. | This setting should be optimal for most databases. However, very large tables (1m rows or more) in which rows are added in a skewed fashion may need to be autoanalyzed at a lower percentage, such as 5% or even 1%. | |
Maintenance | Autovacuum | autovacuum_analyze_threshold | integer | 50 | default | 0 to 2147483647 | sighup | Minimum number of tuple inserts, updates, or deletes prior to analyze. | ||
Maintenance | Autovacuum | autovacuum_freeze_max_age | integer | 200000000 | 500000000 | 100000 to 2000000000 | postmaster | Age at which to autovacuum a table to prevent transaction ID wraparound. | Triggers autovacuum automatically if a table is about to suffer from XID rollover. The setting is very conservative, and should probably be increased to 500million, but not higher. | |
Maintenance | Autovacuum | autovacuum_max_workers | integer | 3 | default | 1 to 262143 | postmaster | Sets the maximum number of simultaneously running autovacuum worker processes. | If you have an installation with many tables (100's to 1000's) or with some tables which autovacuum takes hours to process, you may want to add additional autovacuum workers so that multiple tables can be vacuumed at once. Be conservative, though, as each autovacuum worker will utilize a separate CPU core, memory and I/O. | |
Maintenance | Autovacuum | autovacuum_multixact_freeze_max_age | integer | 400000000 | default | 10000 to 2000000000 | postmaster | Multixact age at which to autovacuum a table to prevent multixact wraparound. | Triggers autovacuum automatically when the oldest “multixact” (a kind of lock transaction) is more than this old. Do not raise past 1billion. | |
Maintenance | Autovacuum | autovacuum_naptime | integer | 60 | default | 1s to 2147483s | sighup | Time to sleep between autovacuum runs. | Decrease this to 30s or 15s if you have a large number (100's) of tables, or if you otherwise see from pg_stat_user_tables that autovacuum is not keeping up. | |
Maintenance | Autovacuum | autovacuum_vacuum_cost_delay | integer | 20 | default | -1ms to 100ms | sighup | Vacuum cost delay in milliseconds, for autovacuum. | If autovacuum is having too much of a performance impact on running queries, you might want to increase this setting to 50ms. However, this will also cause individual vacuum tasks to take longer. | |
Maintenance | Autovacuum | autovacuum_vacuum_cost_limit | integer | -1 | default | -1 to 10000 | sighup | Vacuum cost amount available before napping, for autovacuum. | ||
Maintenance | Autovacuum | autovacuum_vacuum_scale_factor | real | 0.2 | default | 0 to 100 | sighup | Number of tuple updates or deletes prior to vacuum as a fraction of reltuples. | ||
Maintenance | Autovacuum | autovacuum_vacuum_threshold | integer | 50 | default | 0 to 2147483647 | sighup | Minimum number of tuple updates or deletes prior to vacuum. | ||
Maintenance | Autovacuum | autovacuum_work_mem | memory | -1 | AvRAM / workers / 4 | -1kB to 2147483647kB | sighup | Sets the maximum memory to be used by each autovacuum worker process. | Set a limit on this which is based on the number of autovac workers you expect to have running. | |
Reporting and Logging | Where to Log | log_destination | string | csvlog | varies | sighup | Sets the destination for server log output. | Your choice of log destination depends on your system administration plans and the status of your server. “syslog” or “eventlog” (Windows) are good choices for most development servers, because they can support centralized log monitors. For development and testing, however, “csvlog” is probably the most useful, as it allows you to run queries against the log contents. | ||
Reporting and Logging | Where to Log | log_directory | string | pg_log | varies | sighup | Sets the destination directory for log files. | If you are having PostgreSQL keep its own activity logs on a production server, it's probably a good idea to locate them on separate storage from the database and transaction log. | ||
Reporting and Logging | Where to Log | log_file_mode | integer | 600 | default | 0 to 511 | sighup | Sets the file permissions for log files. | … unless you need to share the log with Postgres' unix group, in which case set it to 660. | |
Reporting and Logging | Where to Log | log_filename | string | postgresql-%Y-%m-%d_%H%M%S.log | varies | sighup | Sets the file name pattern for log files. | If you want your logs to rotate automatically without needing a cron job to delete old logs, try naming them after the days of the week or the month so they overwrite automatically (i.e. 'postgresql-%a' or 'postgresql-%d'). This also helps with log analysis. | ||
Reporting and Logging | Where to Log | logging_collector | bool | on | on | postmaster | Start a subprocess to capture stderr output and/or csvlogs into log files. | Only relevant for “csvlog” and “stderr”. | ||
Reporting and Logging | Where to Log | log_rotation_age | integer | 1440 | default | 0min to 35791394min | sighup | Automatic log file rotation will occur after N minutes. | 1d is generally good for production. Set to 1h to rotate logs hourly when doing performance analysis. | |
Reporting and Logging | Where to Log | log_rotation_size | memory | 10MB | 1GB | 0kB to 2097151kB | sighup | Automatic log file rotation will occur after N kilobytes. | Default is quite small if you have any extra logging turned on at all. Increase to avoid the creation of additional log segments with hard-to-predict names. | |
Reporting and Logging | Where to Log | log_truncate_on_rotation | bool | off | on | sighup | Truncate existing log files of same name during log rotation. | Set to “on” for production with a reusable logfile name to limit log accumulation if you don't have a sysadmin script to do so. | ||
Reporting and Logging | Where to Log | syslog_facility | string | LOCAL0 | varies | local0,local1,local2,local3,local4,local5,local6,local7 | sighup | Sets the syslog "facility" to be used when syslog enabled. | Change the logserver facility if you are having a conflict with other applications. | |
Reporting and Logging | Where to Log | syslog_ident | string | postgres | POSTGRES_$HOST | sighup | Sets the program name used to identify PostgreSQL messages in syslog. | If using a centralized logserver or if you have multiple Postgres instances, you probably want to identify your postgresql instance by hostname. | ||
Reporting and Logging | When to Log | client_min_messages | ENUM | notice | default | debug5,debug4,debug3,debug2,debug1,log,notice,warning,error | user | Sets the message levels that are sent to the client. | Unless doing interactive debugging, then you want it set to DEBUG1-5. If you have a client application which is confused by some of PostgreSQL's WARNINGs then you may want to set this to ERROR. | |
Reporting and Logging | When to Log | log_autovacuum_min_duration | integer | -1 | 1min | -1ms to 2147483647ms | sighup | Sets the minimum execution time above which autovacuum actions will be logged. | Logs all autovacuum actions which take more than the specified time. Useful for figuring out if autovacuum is bogging down your system or blocking. | |
Reporting and Logging | When to Log | log_error_verbosity | ENUM | default | default | terse,default,verbose | superuser | Sets the verbosity of logged messages. | Unless doing intensive debugging. Alternately, set to TERSE if managing log volume is becoming a problem. | |
Reporting and Logging | When to Log | log_min_duration_statement | integer | -1 | 1min | -1ms to 2147483647ms | superuser | Sets the minimum execution time above which statements will be logged. | Possibly the most generally useful log setting for troubleshooting performance, especially on a production server. Records only long-running queries for analysis; since these are often your "problem" queries, these are the most useful ones to know about. Used for pg_fouine. | |
Reporting and Logging | When to Log | log_min_error_statement | ENUM | error | default | debug5,debug4,debug3,debug2,debug1,info,notice,warning,error,log,fatal,panic | superuser | Causes all statements generating error at or above this level to be logged. | Logs SQL statements which error. If you have an application which routinely generates errors and can't fix it, then raise the level to FATAL or PANIC. | |
Reporting and Logging | When to Log | log_min_messages | ENUM | notice | default | debug5,debug4,debug3,debug2,debug1,info,notice,warning,error,log,fatal,panic | superuser | Sets the message levels that are logged. | Unless doing serious troubleshooting. If you want to output parses and plans, set to DEBUG1. | |
Reporting and Logging | What to Log | debug_pretty_print | bool | off | on | user | Indents parse and plan tree displays. | For debugging a testing machine. Do not set in production. | ||
Reporting and Logging | What to Log | debug_print_parse | bool | off | default | user | Logs each query's parse tree. | For debugging a testing machine. Do not set in production. | ||
Reporting and Logging | What to Log | debug_print_plan | bool | off | default | user | Logs each query's execution plan. | For debugging a testing machine. Do not set in production. | ||
Reporting and Logging | What to Log | debug_print_rewritten | bool | off | default | user | Logs each query's rewritten parse tree. | For debugging a testing machine. Do not set in production. | ||
Reporting and Logging | What to Log | log_checkpoints | bool | off | varies | sighup | Logs each checkpoint. | When doing performance analysis, it's often a good idea to turn on most of the logging options and log them to a CSVlog. | ||
Reporting and Logging | What to Log | log_connections | bool | off | varies | superuser-backend | Logs each successful connection. | Useful for performance analysis. | ||
Reporting and Logging | What to Log | log_disconnections | bool | off | varies | superuser-backend | Logs end of a session, including duration. | Useful for performance analysis. | ||
Reporting and Logging | What to Log | log_duration | bool | on | varies | superuser | Logs the duration of each completed SQL statement. | Useful for performance analysis. | ||
Reporting and Logging | What to Log | log_hostname | bool | off | off | sighup | Logs the host name in the connection logs. | As this setting requires resolution of each connecting hostname, it's pretty much always too expensive to have on, even when troubleshooting. | ||
Reporting and Logging | What to Log | log_line_prefix | string | default | sighup | Controls information prefixed to each log line. | Primarily useful for providing extra information when logging to syslog or eventlog. Try "%h:%d:%u:%c %t" for this. | |||
Reporting and Logging | What to Log | log_lock_waits | bool | off | varies | superuser | Logs long lock waits. | Useful for performance analysis. | ||
Reporting and Logging | What to Log | log_replication_commands | bool | off | on | superuser | Logs each replication command. | … assuming you're monitoring replication status, which you should. | ||
Reporting and Logging | What to Log | log_statement | ENUM | none | varies | none,ddl,mod,all | superuser | Sets the type of statements logged. | For exhaustive performance analysis on test systems, set to 'all'. Most production setups will just want to use 'ddl' to make sure to record database-altering actions, but very secure setups may want to use 'mod' or even 'all'. Can produce a lot of log volume. | |
Reporting and Logging | What to Log | log_temp_files | memory | -1 | varies | -1kB to 2147483647kB | superuser | Log the use of temporary files larger than this number of kilobytes. | This logger is used for troubleshooting sorts and other activities which are spilling to disk. If you use it at all, it's probably good to set it a something low like 1kB so that you know each query that spilled to disk, since any disk spill at all causes a dramatic slowdown in the query. Can be used to see if you need more work_mem, temp_mem or maintenance_work_mem. | |
Reporting and Logging | What to Log | log_timezone | string | per ENV | local timezone | sighup | Sets the time zone to use in log messages. | To avoid confusion, it's often useful to log to the timezone where the DBA or sysadmin lives. | ||
Reporting and Logging | What to Log | syslog_sequence_numbers | bool | on | default | sighup | Add sequence number to syslog messages to avoid duplicate suppression. | |||
Reporting and Logging | What to Log | syslog_split_messages | bool | on | default | sighup | Split messages sent to syslog by lines and to fit into 1024 bytes. | |||
Lock Management | deadlock_timeout | time | 1sec | default | 1ms to 2147483647ms | superuser | Sets the time to wait on a lock before checking for deadlock. | Default is fine, except when you are troubleshooting/monitoring locks. In that case, you may want to lower it to as little as 50ms. | ||
Lock Management | max_locks_per_transaction | integer | 64 | default | 10 to 2147483647 | postmaster | Sets the maximum number of locks per transaction. | Some databases with very complex schema or with many long-running tranactions need a higher amount. This is rare though. | ||
Lock Management | max_pred_locks_per_page | integer | 2 | default | 0 to 2147483647 | sighup | Sets the maximum number of predicate-locked tuples per page. | |||
Lock Management | max_pred_locks_per_relation | integer | -2 (disabled) | -2147483648 to 2147483647 | sighup | Sets the maximum number of predicate-locked pages and tuples per relation. | ||||
Lock Management | max_pred_locks_per_transaction | integer | 64 | default | 10 to 2147483647 | postmaster | Sets the maximum number of predicate locks per transaction. | Raise if you have a lot of tables and are seeing some transactions fail, but modestly as a larger transaction table is expensive. | ||
Locale & Formatting | Display | DateStyle | list | ISO, MDY | default | user | Sets the display format for date and time values. | Should be set according to the format in which you expect to receive date information. | ||
Locale & Formatting | Display | extra_float_digits | integer | 0 | default | -15 to 3 | user | Sets the number of digits displayed for floating-point values. | Only significant for applications which do a lot of float calculations, like scientific databases. | |
Locale & Formatting | Display | IntervalStyle | enum | postgres | default | postgres,postgres_verbose,sql_standard,iso_8601 | user | Sets the display format for interval values. | This is just in case your applications are expecting something specific in how INTERVAL strings are output. | |
Locale & Formatting | Display | TimeZone | string | per ENV | default | user | Sets the time zone for displaying and interpreting time stamps. | To avoid a lot of confusion, make sure this is set to your local timeszone. If the server covers multiple time zones, then this should be set on a ROLE or connection basis. | ||
Locale & Formatting | Display | timezone_abbreviations | string | Default | default | user | Selects a file of time zone abbreviations. | See appendencies for alternatives. | ||
Locale & Formatting | Locale | client_encoding | string | per ENV | default | user | Sets the client's character set encoding. | Should match server_encoding unless you have a really good reason why not. | ||
Locale & Formatting | Locale | lc_collate | string | as compiled | N/A | internal | Shows the collation order locale. | Set at initdb time. Displayed for information only. | ||
Locale & Formatting | Locale | lc_ctype | string | as compiled | N/A | internal | Shows the character classification and case conversion locale. | Set at initdb time. Displayed for information only. | ||
Locale & Formatting | Locale | lc_messages | string | as compiled | default | superuser | Sets the language in which messages are displayed. | |||
Locale & Formatting | Locale | lc_monetary | string | as compiled | default | user | Sets the locale for formatting monetary amounts. | |||
Locale & Formatting | Locale | lc_numeric | string | as compiled | default | user | Sets the locale for formatting numbers. | |||
Locale & Formatting | Locale | lc_time | string | as compiled | default | user | Sets the locale for formatting date and time values. | |||
Locale & Formatting | Locale | server_encoding | string | per ENV | N/A | internal | Sets the server (database) character set encoding. | Set at initdb time. Displayed for information only. | ||
Other Settings & Defaults | Identification | application_name | string | psql | name | user | Sets the application name to be reported in statistics and logs. | Set this to a reasonable default for most user sessions; if in the middle of working over your application to support application names, this might be “unknown”. | ||
Other Settings & Defaults | Identification | cluster_name | string | NULL | set | postmaster | Sets the name of the cluster, which is included in the process title. | Should be “postgres-1” or something else identifiable as this specific postmaster. | ||
Other Settings & Defaults | Identification | event_source | string | NULL | set | postmaster | Sets the application name used to identify PostgreSQL messages in the event log. | Should be “postgres-1” or something else identifiable as this specific postmaster. | ||
Other Settings & Defaults | Default Locations | default_tablespace | string | default | user | Sets the default tablespace to create tables and indexes in. | Change this if you want a different tablespace for user-created tables. Generally, better set on a ROLE or session basis. | |||
Other Settings & Defaults | Default Locations | search_path | list | "$user",public | varies | user | Sets the schema search order for names that are not schema-qualified. | Most DBAs either use the default or set search_path on a ROLE or database object basis. The one reason to set it in postgresql.conf is if you are taking the security step of removing the special "public" schema in order to lock down your database. | ||
Other Settings & Defaults | Default Locations | temp_tablespaces | list | default | user | Sets the tablespace(s) to use for temporary tables and sort files. | For applications which create lots of temporary objects, this setting can be used to put the temp space on a faster/separate device, or even a ramdisk. Because it accepts a list, it can even be used to load balance temp object creation among several tablespaces. | |||
Other Settings & Defaults | Libraries | dynamic_library_path | string | $libdir | default | superuser | Sets the path for dynamically loadable modules. | Primarily useful if you've written lots of custom C libraries for your installation and want to organize them into custom directories. | ||
Other Settings & Defaults | Libraries | local_preload_libraries | string | default | user | Lists unprivileged shared libraries to preload into each backend. | This is largely a convenience setting, automatically loading libraries listed without needing an explicit load command. Has no effect on performance. | |||
Other Settings & Defaults | Replication | session_replication_role | ENUM | origin | default | origin,replica,local | superuser | Sets the session's behavior for triggers and rewrite rules. | Only gets changed for databases which are taking part in a replication chain. In that case,"origin" servers fire replication (and other) triggers, and "replica" do not. Part of the generic replication hooks which are used by Slony and Bucardo. | |
Other Settings & Defaults | Statement Behavior | default_transaction_deferrable | bool | off | default | user | Sets the default deferrable status of new transactions. | If you use serializable transactions by default, it may be also useful to set this in order to decrease the overhead of long-running transactions. | ||
Other Settings & Defaults | Statement Behavior | default_transaction_isolation | ENUM | read committed | default | serializable,repeatable read,read committed,read uncommitted | user | Sets the transaction isolation level of each new transaction. | Relates to transaction_isolation. Better set on a session or transaction basis as transaction_isolation in order to support specific types of transaction conflict resolution. | |
Other Settings & Defaults | Statement Behavior | default_transaction_read_only | bool | off | default | user | Sets the default read-only status of new transactions. | This setting is mainly useful for preventing yourself from accidentally changing data. It is not really a security setting, as anyone can revoke it on their own session. Better set on a session or ROLE level. Will show up as TRUE if you are on a replication standby. | ||
Other Settings & Defaults | Statement Behavior | statement_timeout | time | 0 | varies | 0ms to 2147483647ms | user | Sets the maximum allowed duration of any statement. | Defaults to 0, meaning no timeout. For most web applications, it's a good idea to set a default timeout, such as 60s to prevent runaway queries from bogging the server. If set, though, you need to remember to set (at the ROLE or session level) a higher statement_timeout for expected long-running maintenance or batch operations. | |
Other Settings & Defaults | Statement Behavior | transaction_deferrable | bool | off | user | Whether to defer a read-only serializable transaction until it can be executed with no possible serialization failures. | ||||
Other Settings & Defaults | Statement Behavior | transaction_isolation | string | read committed | user | Sets the current transaction's isolation level. | Set per session if you need, for example, SERIALIZABLE semantics to prevent data conflicts for multi-step transactions. | |||
Other Settings & Defaults | Statement Behavior | transaction_read_only | bool | off | user | Sets the current transaction's read-only status. | Sets the current transaction to read only. Useful as part of a SQL injection prevention program. Shows as TRUE on replication standbys. | |||
Other Settings & Defaults | Text Search | default_text_search_config | string | per ENV | default | user | Sets default text search configuration. | Set to the most common language used by the users, so that they don't have to pass the language parameter when calling TSearch functions. | ||
Other Settings & Defaults | Text Search | gin_fuzzy_search_limit | integer | 0 | varies | 0 to 2147483647 | user | Sets the maximum allowed result for exact search by GIN. | If you're going to use GIN queries in a web application, it's generally useful to set a limit on how many rows can be returned from the index just for response times. However, the maximum number needs to depend on your application; what do users see as an acceptable expression of "many"? | |
Other Settings & Defaults | XML | xmlbinary | ENUM | base64 | varies | base64,hex | user | Sets how binary values are to be encoded in XML. | Set to whatever your client application supports. | |
Other Settings & Defaults | XML | xmloption | ENUM | content | default | content,document | user | Sets whether XML data in implicit parsing and serialization operations is to be considered as documents or content fragments. | ||
Other Settings & Defaults | Other Defaults | check_function_bodies | bool | on | default | user | Check function bodies during CREATE FUNCTION. | You only really want to turn this off to resolve circular dependancies, and that can be done on a per-session basis. In general, checking for syntax errors in PL/pgSQL functions is a very good idea. | ||
Other Settings & Defaults | Other Defaults | exit_on_error | bool | off | default | user | Terminate session on any error. | |||
Other Settings & Defaults | Other Defaults | gin_pending_list_limit | memory | 4MB | default | 64kB to 2147483647kB | user | Sets the maximum size of the pending list for GIN index. | Unless you have a lot of GIN indexed data and have time to test the performance of fastupdate. Even then, it's probably better to set it on individual indexes. | |
Other Settings & Defaults | Other Defaults | restart_after_crash | bool | off | default | sighup | Reinitialize server after backend crash. | … unless deliberately running postgres in “ephemeral mode” | ||
Other Settings & Defaults | Other Defaults | row_security | bool | on | on | user | Enable row security. | … except when testing row security policies. | ||
Other Settings & Defaults | Other Defaults | session_preload_libraries | string | NULL | default | superuser | Lists shared libraries to preload into each backend. | Special uses for debugging or for loading application-specific extensions. | ||
Other Settings & Defaults | Timeouts | idle_in_transaction_session_timeout | time | off | 1hr | 0ms to 2147483647ms | user | Sets the maximum allowed duration of any idling transaction. | Set to 1 hour maximum, or as low as 1 minute if you know your query load well. Idle transactions are bad news. | |
Other Settings & Defaults | Timeouts | lock_timeout | time | 0 off | default | 0ms to 2147483647ms | user | Sets the maximum allowed duration of any wait for a lock. | … but consider setting this per application or per query for any explicit locking attempts. | |
Other Settings & Defaults | Timeouts | old_snapshot_threshold | time | -1 (disabled) | 2hrs | -1min to 86400min | postmaster | Time before a snapshot is too old to read pages changed after the snapshot was taken. | … or the length of the longest transaction you expect to run + 1 hour. | |
Other Settings & Defaults | Previous PostgreSQL Versions | operator_precedence_warning | bool | off | default | user | Emit a warning for constructs that changed meaning since PostgreSQL 9.4. | |||
Other Settings & Defaults | Previous PostgreSQL Versions | quote_all_identifiers | bool | off | default | user | When generating SQL fragments, quote all identifiers. | |||
Preset Options | block_size | integer | 8192 | N/A | 8192 to 8192 | internal | Shows the size of a disk block. | Informational: lets you know of non-standard installation or compile options. | ||
Preset Options | data_checksums | bool | off | on | internal | Shows whether data checksums are turned on for this cluster. | This has to be set at initdb time, and does create a significant amount of extra I/O. However, it will save you from a corrupt database down the line, so if you're not performance-constrained, always use it. | |||
Preset Options | integer_datetimes | bool | off | N/A | internal | Datetimes are integer based. | Informational: lets you know of non-standard installation or compile options. | |||
Preset Options | max_function_args | integer | 100 | N/A | 100 to 100 | internal | Shows the maximum number of function arguments. | Informational: lets you know of non-standard installation or compile options. | ||
Preset Options | max_identifier_length | integer | 63 | N/A | 63 to 63 | internal | Shows the maximum identifier length. | Informational: lets you know of non-standard installation or compile options. | ||
Preset Options | max_index_keys | integer | 32 | N/A | 32 to 32 | internal | Shows the maximum number of index keys. | Informational: lets you know of non-standard installation or compile options. | ||
Preset Options | segment_size | integer | 131072 | 1310728kB to 1310728kB | internal | Shows the number of pages per disk file. | Informational: lets you know of non-standard installation or compile options. | |||
Preset Options | server_version | string | 08/03/00 | N/A | internal | Shows the server version. | Informational: lets you know of non-standard installation or compile options. | |||
Preset Options | server_version_num | integer | 80300 | N/A | 100003 to 100003 | internal | Shows the server version as an integer. | Informational: lets you know of non-standard installation or compile options. | ||
Preset Options | wal_block_size | integer | 8192 | 8192 to 8192 | internal | Shows the block size in the write ahead log. | Informational: lets you know of non-standard installation or compile options. | |||
Preset Options | wal_segment_size | integer | 2048 | 20488kB to 20488kB | internal | Shows the number of pages per write ahead log segment. | Informational: lets you know of non-standard installation or compile options. | |||
Version and Platform Compatibility | Other Platforms and Clients | transform_null_equals | bool | off | off | user | Treats "expr=NULL" as "expr IS NULL". | Provided for compatibility with Microsoft Access and similar broken applications which treat "= NULL" as the same as "IS NULL". | ||
Version and Platform Compatibility | Previous PostgreSQL Versions | array_nulls | bool | on | default | user | Enable input of NULL elements in arrays. | Provided for compatibility with 7.4 behavior. | ||
Version and Platform Compatibility | Previous PostgreSQL Versions | backslash_quote | ENUM | safe_encoding | default | safe_encoding,on,off | user | Sets whether "\'" is allowed in string literals. | If you have cleaned up your application code, you can set this to 'off' to help lock down the database. Older PHP applications will require the insecure setting of 'on'. | |
Version and Platform Compatibility | Previous PostgreSQL Versions | bytea_output | enum | hex | hes | escape,hex | user | Sets the output format for bytea. | ||
Version and Platform Compatibility | Previous PostgreSQL Versions | default_with_oids | bool | off | default | user | Create new tables with OIDs by default. | Provided for consistency with 7.3 behavior. Since this creates an OID for every row, can cause OID wraparound in large databases. | ||
Version and Platform Compatibility | Previous PostgreSQL Versions | escape_string_warning | bool | on | off | user | Warn about backslash escapes in ordinary string literals. | Useful for providing warnings for interpreted-language applications which may be engaging in unsafe string escape behavior. Unless you are currently porting or upgrading such an application, though, these warnings are not useful and should be turned off. | ||
Version and Platform Compatibility | Previous PostgreSQL Versions | lo_compat_privileges | bool | off | superuser | Enables backward compatibility mode for privilege checks on large objects. | ||||
Version and Platform Compatibility | Previous PostgreSQL Versions | standard_conforming_strings | bool | off | on | user | Causes '...' strings to treat backslashes literally. | If you can clean up your application code, this disables use of \ as an escape character except in escaped (E' ') strings. This is both safer, and less likely to result in unexpected output for things like Windows filepaths. | ||
Version and Platform Compatibility | Previous PostgreSQL Versions | synchronize_seqscans | bool | on | on | user | Enable synchronized sequential scans. | This new peformance enhancment can also cause rows to be returned in an order other than physical storage order. For poorly-written older applications, this may break application code; turn it off to disable. | ||
Developer Options | allow_system_table_mods | bool | off | default | postmaster | Allows modifications of the structure of system tables. | Only available in single-user mode; this setting is for initdb and may be used in the future for upgrade-in-place. | |||
Developer Options | debug_assertions | bool | off | default | internal | Shows whether the running server has assertion checks enabled. | Used for debugging PostgreSQL code problems; not for production use. Requires compile options. | |||
Developer Options | ignore_checksum_failure | bool | off | default | superuser | Continues processing after a checksum failure. | For rescuing a corrupt DB | |||
Developer Options | ignore_system_indexes | bool | off | default | backend | Disables reading from system indexes. | Useful for salvaging data from a corrupted database. | |||
Developer Options | post_auth_delay | integer | 0 | default | 0s to 2147s | backend | Waits N seconds on connection startup after authentication. | Primarily used for attaching debuggers to sessions. | ||
Developer Options | pre_auth_delay | integer | 0 | default | 0s to 60s | sighup | Waits N seconds on connection startup before authentication. | Primarily used for attaching debuggers to sessions. | ||
Developer Options | trace_notify | bool | off | default | user | Generates debugging output for LISTEN and NOTIFY. | The various TRACE options are for debugging specific behaviors interactively. Many of them require compile-time options. trace_notice is for debugging listen/notice. | |||
Developer Options | trace_recovery_messages | enum | log | debug5,debug4,debug3,debug2,debug1,log,notice,warning,error | sighup | Enables logging of recovery-related debugging information. | For troubleshooting replication/PITR failures. | |||
Developer Options | trace_sort | bool | off | default | user | Emit information about resource usage in sorting. | For debugging sorts. | |||
Developer Options | wal_consistency_checking | string | empty | debugging only | superuser | Sets the WAL resource managers for which WAL consistency checks are done. | ||||
Developer Options | zero_damaged_pages | bool | off | off | superuser | Continues processing past damaged page headers. | Used for salvaging data from a known-bad database. You should always make a binary backup before using this option, and it should not be used while users are allowed to connect. After damaged pages are erased, other kinds of data intergrity errors may persist (like broken PKs and FKs). ZDP should generally be used to get your DB to a stage where the data can be dumped and loaded into a new database. |