Server Run-time Environment This chapter discusses how to set up and run the database server and the interactions with the operating system. The <productname>PostgreSQL</productname> User Account postgres user As with any other server daemon that is connected to outside world, it is advisable to run PostgreSQL under a separate user account. This user account should only own the data that is managed by the server, and should not be shared with other daemons. (For example, using the user nobody is a bad idea.) It is not advisable to install executables owned by this user because compromised systems could then modify their own binaries. To add a Unix user account to your system, look for a command useradd or adduser. The user name postgres is often used but is by no means required. Creating a Database Cluster database cluster data area database cluster Before you can do anything, you must initialize a database storage area on disk. We call this a database cluster. (SQL uses the term catalog cluster instead.) A database cluster is a collection of databases is accessible by a single instance of a running database server. After initialization, a database cluster will contain a database named template1. As the name suggests, this will be used as a template for subsequently created databases; it should not be used for actual work. (See for information about creating databases.) In file system terms, a database cluster will be a single directory under which all data will be stored. We call this the data directory or data area. It is completely up to you where you choose to store your data. There is no default, although locations such as /usr/local/pgsql/data or /var/lib/pgsql/data are popular. To initialize a database cluster, use the command initdb,initdb which is installed with PostgreSQL. The desired file system location of your database system is indicated by the option, for example $ initdb -D /usr/local/pgsql/data Note that you must execute this command while logged into the PostgreSQL user account, which is described in the previous section. As an alternative to the option, you can set the environment variable PGDATA. PGDATA initdb will attempt to create the directory you specify if it does not already exist. It is likely that it will not have the permission to do so (if you followed our advice and created an unprivileged account). In that case you should create the directory yourself (as root) and change the owner to be the PostgreSQL user. Here is how this might be done: root# mkdir /usr/local/pgsql/data root# chown postgres /usr/local/pgsql/data root# su postgres postgres$ initdb -D /usr/local/pgsql/data initdb will refuse to run if the data directory looks like it it has already been initialized. Because the data directory contains all the data stored in the database, it is essential that it be secured from unauthorized access. initdb therefore revokes access permissions from everyone but the PostgreSQL user. However, while the directory contents are secure, the default client authentication setup allows any local user to connect to the database and even become the database superuser. If you do not trust other local users, we recommend you use one of initdb's , or option to assign a password to the database superuser.passwordof the superuser After initdb, modify the pg_hba.conf file to use md5 or password instead of trust authentication before you start the server for the first time. (Other approaches include using ident authentication or file system permissions to restrict connections. See for more information.) initdb also initializes the default localelocale for the database cluster. Normally, it will just take the locale settings in the environment and apply them to the initialized database. It is possible to specify a different locale for the database; more information about that can be found in . The sort order used within a particular database cluster is set by initdb and cannot be changed later, short of dumping all data, rerunning initdb, and reloading the data. So it's important to make this choice correctly the first time. Starting the Database Server Before anyone can access the database, you must start the database server. The database server program is called postmaster.postmaster The postmaster must know where to find the data it is supposed to use. This is done with the option. Thus, the simplest way to start the server is: $ postmaster -D /usr/local/pgsql/data which will leave the server running in the foreground. This must be done while logged into the PostgreSQL user account. Without , the server will try to use the data directory named by the environment variable PGDATA. If that variable is not provided either, it will fail. Normally it is better to start the postmaster in the background. For this, use the usual shell syntax: $ postmaster -D /usr/local/pgsql/data >logfile 2>&1 & It is important to store the server's stdout and stderr output somewhere, as shown above. It will help for auditing purposes and to diagnose problems. (See for a more thorough discussion of log file handling.) The postmaster also takes a number of other command line options. For more information, see the reference page and below. This shell syntax can get tedious quickly. Therefore the shell script wrapper pg_ctlpg_ctl is provided to simplify some tasks. For example: pg_ctl start -l logfile will start the server in the background and put the output into the named log file. The option has the same meaning here as in the postmaster. pg_ctl is also capable of stopping the server. Normally, you will want to start the database server when the computer boots.bootingstarting the server during Autostart scripts are operating-system-specific. There are a few distributed with PostgreSQL in the contrib/start-scripts directory. Installing one will require root privileges. Different systems have different conventions for starting up daemons at boot time. Many systems have a file /etc/rc.local or /etc/rc.d/rc.local. Others use rc.d directories. Whatever you do, the server must be run by the PostgreSQL user account and not by root or any other user. Therefore you probably should form your commands using su -c '...' postgres. For example: su -c 'pg_ctl start -D /usr/local/pgsql/data -l serverlog' postgres Here are a few more operating-system-specific suggestions. (In each case be sure to use the proper installation directory and user name where we show generic values.) For FreeBSD, look at the file contrib/start-scripts/freebsd in the PostgreSQL source distribution. FreeBSDstart script On OpenBSD, add the following lines to the file /etc/rc.local: OpenBSDstart script if [ -x /usr/local/pgsql/bin/pg_ctl -a -x /usr/local/pgsql/bin/postmaster ]; then su - -c '/usr/local/pgsql/bin/pg_ctl start -l /var/postgresql/log -s' postgres echo -n ' postgresql' fi On Linux systems either add Linuxstart script /usr/local/pgsql/bin/pg_ctl start -l logfile -D /usr/local/pgsql/data to /etc/rc.d/rc.local or look at the file contrib/start-scripts/linux in the PostgreSQL source distribution. On NetBSD, either use the FreeBSD or Linux start scripts, depending on preference. NetBSDstart script On Solaris, create a file called /etc/init.d/postgresql that contains the following line: Solarisstart script su - postgres -c "/usr/local/pgsql/bin/pg_ctl start -l logfile -D /usr/local/pgsql/data" Then, create a symbolic link to it in /etc/rc3.d as S99postgresql. While the postmaster is running, its PID is stored in the file postmaster.pid in the data directory. This is used to prevent multiple postmaster processes running in the same data directory and can also be used for shutting down the postmaster process. Server Start-up Failures There are several common reasons the server might fail to start. Check the server's log file, or start it by hand (without redirecting standard output or standard error) and see what error messages appear. Below we explain some of the most common error messages in more detail. LOG: could not bind IPv4 socket: Address already in use HINT: Is another postmaster already running on port 5432? If not, wait a few seconds and retry. FATAL: could not create TCP/IP listen socket This usually means just what it suggests: you tried to start another postmaster on the same port where one is already running. However, if the kernel error message is not Address already in use or some variant of that, there may be a different problem. For example, trying to start a postmaster on a reserved port number may draw something like: $ postmaster -p 666 LOG: could not bind IPv4 socket: Permission denied HINT: Is another postmaster already running on port 666? If not, wait a few seconds and retry. FATAL: could not create TCP/IP listen socket A message like FATAL: could not create shared memory segment: Invalid argument DETAIL: Failed system call was shmget(key=5440001, size=4011376640, 03600). probably means your kernel's limit on the size of shared memory is smaller than the work area PostgreSQL is trying to create (4011376640 bytes in this example). Or it could mean that you do not have System-V-style shared memory support configured into your kernel at all. As a temporary workaround, you can try starting the server with a smaller-than-normal number of buffers ( switch). You will eventually want to reconfigure your kernel to increase the allowed shared memory size. You may also see this message when trying to start multiple servers on the same machine, if their total space requested exceeds the kernel limit. An error like FATAL: could not create semaphores: No space left on device DETAIL: Failed system call was semget(5440126, 17, 03600). does not mean you've run out of disk space. It means your kernel's limit on the number of System V semaphores is smaller than the number PostgreSQL wants to create. As above, you may be able to work around the problem by starting the server with a reduced number of allowed connections ( switch), but you'll eventually want to increase the kernel limit. If you get an illegal system call error, it is likely that shared memory or semaphores are not supported in your kernel at all. In that case your only option is to reconfigure the kernel to enable these features. Details about configuring System V IPC facilities are given in . Client Connection Problems Although the error conditions possible on the client side are quite varied and application-dependent, a few of them might be directly related to how the server was started up. Conditions other than those shown below should be documented with the respective client application. psql: could not connect to server: Connection refused Is the server running on host "server.joe.com" and accepting TCP/IP connections on port 5432? This is the generic I couldn't find a server to talk to failure. It looks like the above when TCP/IP communication is attempted. A common mistake is to forget to configure the server to allow TCP/IP connections. Alternatively, you'll get this when attempting Unix-domain socket communication to a local server: psql: could not connect to server: No such file or directory Is the server running locally and accepting connections on Unix domain socket "/tmp/.s.PGSQL.5432"? The last line is useful in verifying that the client is trying to connect to the right place. If there is in fact no server running there, the kernel error message will typically be either Connection refused or No such file or directory, as illustrated. (It is important to realize that Connection refused in this context does not mean that the server got your connection request and rejected it. That case will produce a different message, as shown in .) Other error messages such as Connection timed out may indicate more fundamental problems, like lack of network connectivity. 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 the four types: boolean, integer, floating point, and string. Boolean values are ON, OFF, TRUE, FALSE, YES, NO, 1, 0 (case-insensitive) or any non-ambiguous prefix of these. One way to set these parameters is to edit the file postgresql.confpostgresql.conf in the data directory. (A default file is installed there.) An example of what this file might look like is: # This is a comment log_connections = yes 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 should 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. Occasionally it is also useful to give a command line option to one particular session only. The environment variable PGOPTIONS can be used for this purpose on the client side: env PGOPTIONS='-c geqo=off' psql (This works for any libpq-based client application, not just psql.) Note that this won't work for parameters that are fixed when the server is started, such as the port number. Furthermore, it is possible to assign a set of option settings to a user or a database. Whenever a session is started, the default settings for the user and database involved are loaded. The commands 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 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. Configuration Files pgdata (string) Specifies the directory to use for data storage (everything except configuration files). hba_conf (string) Specifies the file name to use for configuration of host-based authentication (HBA). ident_conf (string) Specifies the file name to use for configuration of ident authentication. external_pidfile (string) Specifies the location of an additional postmaster process-id (PID) file for use by server administration programs. Connections and Authentication Connection Settings listen_addresses (string) 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 space-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 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) 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 these parameters, if necessary. superuser_reserved_connections (integer) 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) 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) Sets the group owner of the Unix domain socket. (The owning user of the socket is always the user that starts the server.) In combination with the option unix_socket_permissions this can be used as an additional access control mechanism for this socket type. By default this is the empty string, which uses the default group for the current user. This option can only be set at server start. unix_socket_permissions (integer) Sets the access permissions of the Unix domain socket. Unix domain sockets use the usual Unix file system permission set. The option value is expected to be an numeric mode specification in the form accepted by the chmod and umask system calls. (To use the customary octal format the number must start with a 0 (zero).) The default permissions are 0777, meaning anyone can connect. Reasonable alternatives are 0770 (only user and group, see also under unix_socket_group) and 0700 (only user). (Note that actually for a Unix domain socket, only write permission matters and there is no point in setting or revoking read or execute permissions.) This access control mechanism is independent of the one described in . This option can only be set at server start. rendezvous_name (string) Specifies the Rendezvous broadcast name. By default, the computer name is used, specified as an empty string ''. This option is only meaningful on platforms that support Rendezvous. This option can only be set at server start. Security and Authentication authentication_timeout (integer) timeoutclient authentication client authenticationtimeout during 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 ssl (boolean) Enables SSL connections. Please read before using this. The default is off. password_encryption (boolean) 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) Sets the location of the Kerberos server key file. See for details. db_user_namespace (boolean) This allows per-database user names. It is off by default. If this is on, you should create users as username@dbname. When username is passed by a connecting client, @ and the database name is appended to the user name and that database-specific user name is looked up by the server. Note that when you create users with names containing @ within the SQL environment, you will need to quote the user name. With this option enabled, you can still create ordinary global users. Simply append @ when specifying the user name in the client. The @ will be stripped off before the user name is looked up by the server. 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) 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 these parameters, if necessary. work_mem (integer) 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) 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) 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 max_fsm_pages (integer) 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) Sets the maximum number of relations (tables and indexes) for which free space will be tracked in the shared free-space map. Roughly fifty bytes of shared memory are consumed for each slot. The default is 1000. This option can only be set at server start. Kernel Resource Usage max_files_per_process (integer) 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 This variable specifies one or more shared libraries that are to be preloaded at server start. A parameterless initialization function can optionally be called for each library. To specify that, add a colon and the name of the initialization function after the library name. For example '$libdir/mylib:mylib_init' would cause mylib to be preloaded and mylib_init to be executed. If more than one library is to be loaded, separate their names with commas. If mylib or mylib_init are not found, the server will fail to start. PostgreSQL procedural language libraries may be preloaded in this way, typically by using the syntax '$libdir/plXXX:plXXX_init' where XXX is pgsql, perl, tcl, or python. By preloading a shared library (and initializing it if applicable), the library startup time is avoided when the library is first used. However, the time to start each new server process may increase, even if that process never uses the library. 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_naptime). 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 some 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_naptime variable to a nonzero value. vacuum_cost_page_hit (integer) 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) 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) 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) The accumulated cost that will cause the vacuuming process to briefly nap. The default value is 200. vacuum_cost_naptime (integer) The length of time, in milliseconds, that the process will nap 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 however that on many systems, the effective resolution of sleep delays is 10 milliseconds; setting vacuum_cost_naptime 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. There are certain bulk 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 naptime is calculated as vacuum_cost_naptime * accumulated_balance / vacuum_cost_limit with a maximum of vacuum_cost_naptime * 4. Write Ahead Log See also for details on WAL tuning. Settings fsync 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. (Crashes of the database server itself are not related to this.) However, using fsync() results in a performance penalty: when a transaction is committed, PostgreSQL must wait for the operating system to flush the write-ahead log to disk. When fsync is disabled, the operating system is allowed to do its best in buffering, ordering, and delaying writes. This can result in significantly improved performance. However, if the system crashes, the results of the last few committed transactions may be lost in part or whole. In the worst case, unrecoverable data corruption may occur. Due to the risks involved, there is no universally correct setting for fsync. Some administrators always disable fsync, while others only turn it off for bulk loads, where there is a clear restart point if something goes wrong, whereas some administrators always leave fsync enabled. The default is to enable fsync, for maximum reliability. If you trust your operating system, your hardware, and your utility company (or your battery backup), you can consider disabling fsync. This option can only be set at server start or in the postgresql.conf file. wal_sync_method (string) Method used for forcing WAL updates out to disk. Possible values are fsync (call fsync() at each commit), fdatasync (call fdatasync() at each commit), open_sync (write WAL files with open() option O_SYNC), and open_datasync (write WAL files with open() option O_DSYNC). Not all of these choices are available on all platforms. This option can only be set at server start or in the postgresql.conf file. wal_buffers (integer) Number of disk-page buffers in shared memory for WAL logging. The default is 8. This option can only be set at server start. Checkpoints checkpoint_segments (integer) 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) 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) Write a message to the server logs if checkpoints caused by the filling of checkpoint segment files happens more frequently than this number of seconds. The default is 30 seconds. Zero turns off the warning. commit_delay (integer) Time delay between writing a commit record to the WAL buffer and flushing the buffer out to disk, in microseconds. A nonzero delay allows multiple transactions to be committed with only one fsync() system call, if system load is high enough additional transactions may become ready to commit within the given interval. But the delay is just wasted if no other transactions become ready to commit. Therefore, the delay is only performed if at least commit_siblings other transactions are active at the instant that a server process has written its commit record. The default is zero (no delay). commit_siblings (integer) 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. Archiving archive_command (string) The shell command to execute to archive a completed segment of the WAL file series. If this is an empty string (which is the default), WAL archiving is disabled. Any %p in the string is replaced by the absolute path of the file to archive, while any %f is replaced by the file name only. Write %% if you need 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. Query Planning Planner Method Configuration These configuration parameters provide a crude method for influencing the query plans chosen by the query optimizer. If the default plan chosen by the optimizer for a particular query is not optimal, a temporary solution may be found by using one of these configuration parameters to force the optimizer to choose a better plan. Other ways to improve the quality of the plans chosen by the optimizer include configuring the , running more frequently, increasing the value of the configuration parameter, and increasing the amount of statistics collected for a particular column using ALTER TABLE SET STATISTICS. enable_hashagg (boolean) Enables or disables the query planner's use of hashed aggregation plan types. The default is on. This is used for debugging the query planner. enable_hashjoin (boolean) Enables or disables the query planner's use of hash-join plan types. The default is on. This is used for debugging the query planner. index scan enable_indexscan (boolean) Enables or disables the query planner's use of index-scan plan types. The default is on. This is used for debugging the query planner. enable_mergejoin (boolean) Enables or disables the query planner's use of merge-join plan types. The default is on. This is used for debugging the query planner. enable_nestloop (boolean) Enables or disables the query planner's use of nested-loop join plans. It's not possible to suppress nested-loop joins entirely, but turning this variable off discourages the planner from using one if there are other methods available. The default is on. This is used for debugging the query planner. sequential scan enable_seqscan (boolean) Enables or disables the query planner's use of sequential scan plan types. It's not possible to suppress sequential scans entirely, but turning this variable off discourages the planner from using one if there are other methods available. The default is on. This is used for debugging the query planner. enable_sort (boolean) Enables or disables the query planner's use of explicit sort steps. It's not possible to suppress explicit sorts entirely, but turning this variable off discourages the planner from using one if there are other methods available. The default is on. This is used for debugging the query planner. enable_tidscan (boolean) Enables or disables the query planner's use of TID scan plan types. The default is on. This is used for debugging the query planner. 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) Sets the planner's assumption about the effective size of the disk cache (that is, the portion of the kernel's disk cache that will be used for PostgreSQL data files). This is measured in disk pages, which are normally 8192 bytes each. The default is 1000. random_page_cost (floating point) Sets the query planner's estimate of the cost of a nonsequentially fetched disk page. This is measured as a multiple of the cost of a sequential page fetch. A higher value makes it more likely a sequential scan will be used, a lower value makes it more likely an index scan will be used. The default is four. cpu_tuple_cost (floating point) Sets the query planner's estimate of the cost of processing each row during a query. This is measured as a fraction of the cost of a sequential page fetch. The default is 0.01. cpu_index_tuple_cost (floating point) Sets the query planner's estimate of the cost of processing each index row during an index scan. This is measured as a fraction of the cost of a sequential page fetch. The default is 0.001. cpu_operator_cost (floating point) 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 (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) 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) Controls the tradeoff 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 likelyhood 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) 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) 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) 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) 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 . from_collapse_limit (integer) 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) 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 variable 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 to 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) 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) 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) 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_prefix (string) When redirect_stderr is enabled, this option sets the prefix of the file names of the created log files. The postmaster PID and the current time are appended to this prefix to form an exact log file name. This option can only be set at server start or in the postgresql.conf configuration file. log_rotation_age (integer) 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) 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. syslog_facility (string) 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) 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) 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) Controls which message levels are written to the server log. Valid values are DEBUG5, DEBUG4, DEBUG3, DEBUG2, DEBUG1, INFO, NOTICE, WARNING, ERROR, LOG, FATAL, and PANIC. Each level includes all the levels that follow it. The later the level, the fewer messages are sent to the log. The default is NOTICE. Note that LOG has a different rank here than in client_min_messages. Only superusers can increase this option. log_error_verbosity (string) 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. log_min_error_statement (string) Controls whether or not the SQL statement that causes an error condition will also be recorded in the server log. All SQL statements that cause an error of the specified level, or a higher level, are logged. The default is PANIC (effectively turning this feature off for normal use). Valid values are DEBUG5, DEBUG4, DEBUG3, DEBUG2, DEBUG1, INFO, NOTICE, WARNING, ERROR, FATAL, and PANIC. For example, if you set this to ERROR then all SQL statements causing errors, fatal errors, or panics will be logged. Enabling this option can be helpful in tracking down the source of any errors that appear in the server log. Only superusers can increase this option. log_min_duration_statement (integer) Sets a minimum statement execution time (in milliseconds) for statement to be logged. All SQL statements that run in the time specified or longer will be logged with their duration. Setting this to zero will print all queries and their durations. Minus-one (the default) disables this. For example, if you set it to 250 then all SQL statements that run 250ms or longer will be logged. Enabling this option can be useful in tracking down unoptimized queries in your applications. Only superusers can increase this or set it to minus-one if this option is set by the administrator. silent_mode (boolean) Runs the server silently. If this option is set, the server will automatically run in background and any controlling terminals are disassociated. Thus, no messages are written to standard output or standard error (same effect as postmaster's option). Unless syslog logging 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 transaction 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) These options enable various debugging output to be sent to the client or server log. For each executed query, they print the resulting parse tree, the query rewriter output, or the execution plan. debug_pretty_print indents these displays to produce a more readable but much longer output format. client_min_messages or log_min_messages must be DEBUG1 or lower to send output to the client or server logs. These options are off by default. log_connections (boolean) This outputs a line to the server logs detailing each successful connection. This is off by default, although it is probably very useful. This option can only be set at server start or in the postgresql.conf configuration file. log_disconnections (boolean) This outputs a line in the server logs 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) Causes the duration of every completed statement to be logged. To use this option, it is recommended that you also enable log_statement and if not using syslog log the PID using log_line_prefix so that you can link the statement to the duration using the process ID. The default is off. Only superusers can turn off this option if it is enabled by the administrator. log_line_prefix (string) 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 processes without controlling sessions. Syslog produces its own timestamp 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 Hostname or IP address, and Remote Port Yes %p Process ID No %t Timestamp No %i Command Tag. This is the command which 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 Timestamp Yes %x Does not produce any output, but tells non-session processes to stop at this point in the string. Ignored by session backends. No %% Literal % No log_statement (string) Controls which SQL statement are logged. Valid values are all, ddl, mod, and none. 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 considered for appropriate commands. The default is none. Only superusers can reduce the detail of this option if it has been set by an administrator. The EXECUTE statement 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 a server-side language like PL/pgSQL, 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 the PL/pgSQL keeps a cache of the query plans produced for the SQL statements in the function. log_hostname (boolean) By default, connection logs only show the IP address of the connecting host. If you want it to show the host name you can turn this on, but depending on your host name resolution setup it might impose a non-negligible performance penalty. This option can only be set at server start. Runtime Statistics Statistics Monitoring log_statement_stats (boolean) log_parser_stats (boolean) log_planner_stats (boolean) log_executor_stats (boolean) 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-state statistics. All of these options are disabled by default. Only superusers can turn off any of these options if they have been enabled by the administrator. Query and Index Statistics Collector stats_start_collector (boolean) 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) 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) 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) 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) If on, collected statistics are zeroed out whenever the server is restarted. If off, statistics are accumulated across server restarts. The default is on. This option can only be set at server start. Client Connection Defaults Statement Behavior search_path (string) search_path 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 . check_function_bodies (boolean) This parameter is normally true. When set to false, it disables validation of the function body string in . 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 (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 (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 false (read/write). Consult for more information. statement_timeout (integer) Aborts any statement that takes over the specified number of milliseconds. A value of zero turns off the timer, which is the default value. Locale and Formatting datestyle (string) date style 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) time zone Sets the time zone for displaying and interpreting time stamps. The default is to use whatever the system environment specifies as the time zone. See for more information. australian_timezones (boolean) time zoneAustralian If set to true, ACST, CST, EST, and SAT are interpreted as Australian time zones rather than as North/South American time zones and Saturday. The default is false. significant digits floating-point display 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) character set Sets the client-side encoding (character set). The default is to use the database encoding. lc_messages (string) 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) 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) 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) 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) 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 dynamic loading If a dynamically loadable module needs to be opened and the specified name does not have a directory component (i.e. the name does not contain a slash), the system will search this path for the specified file. (The name that is used is the name specified in the CREATE FUNCTION or LOAD command.) The value for dynamic_library_path has to be a list of absolute directory names separated by colon or, in windows environments with semi-colon. If a directory name starts with the special value $libdir, the compiled-in PostgreSQL package library directory is substituted. This where the modules provided by the PostgreSQL distribution are installed. (Use pg_config --pkglibdir to print the name of this directory.) For example: dynamic_library_path = '/usr/local/lib/postgresql:/home/my_project/lib:$libdir' 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 (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) The shared lock table is sized on the assumption that at most max_locks_per_transaction * max_connections distinct objects will need to be locked at any one time. The default, 64, has historically proven sufficient, but you might need to raise this value if you have clients that touch many different tables in a single transaction. This option can only be set at server start. Version and Platform Compatibility Previous PostgreSQL Versions add_missing_from (boolean) FROMmissing When true, tables that are referenced by a query will be automatically added to the FROM clause if not already present. The default is true for compatibility with previous releases of PostgreSQL. However, this behavior is not SQL-standard, and many people dislike it because it can mask mistakes. Set to false for the SQL-standard behavior of rejecting references to tables that are not listed in FROM. regex_flavor (string) regular expressions 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. sql_inheritance (boolean) 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) This controls whether CREATE TABLE and CREATE TABLE AS will include OIDs in newly-created tables, if neither WITH OIDS or WITHOUT OIDS have been specified. It also determines whether OIDs will be included in the table created by SELECT INTO. In PostgreSQL &version; default_with_oids defaults to true. This is also the behavior of previous versions of PostgreSQL. However, assuming that tables will contain OIDs by default is not encouraged. Therefore, this option will default to false in a future release of PostgreSQL. To ease compatibility with applications that make use of OIDs, this option should left enabled. To ease compatibility with future versions of PostgreSQL, this option should be disabled, and applications that require OIDs on certain tables should explictely specify WITH OIDS when issuing the CREATE TABLE statements for the tables in question. Platform and Client Compatibility transform_null_equals (boolean) IS NULL When turned on, expressions of the form expr = NULL (or NULL = expr) are treated as expr IS NULL, that is, they return true if expr evaluates to the null value, and false otherwise. The correct behavior of expr = NULL is to always return null (unknown). Therefore this option defaults to off. However, filtered forms in Microsoft Access generate queries that appear to use expr = NULL to test for null values, so if you use that interface to access the database you might want to turn this option on. Since expressions of the form expr = NULL always return the null value (using the correct interpretation) they are not very useful and do not appear often in normal applications, so this option does little harm in practice. But new users are frequently confused about the semantics of expressions involving null values, so this option is not on by default. Note that this option only affects the literal = operator, not other comparison operators or other expressions that are computationally equivalent to some expression involving the equals operator (such as IN). Thus, this option is not a general fix for bad programming. Refer to for related information. Compiled-in Options The following options are available read-only, and are determined when PostgreSQL is compiled. As such, they have been excluded from the sample postgresql.conf file. These options determine various aspects of PostgreSQL behavior that may be of interest to certain applications, particularly administrative front-ends. block_size (integer) Shows 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) Shows 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. max_function_args (integer) Shows the maximum number of function arguments. It is determined by the value of FUNC_MAX_ARGS when building the server. The default value is 32. max_identifier_length (integer) Shows 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) Shows 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. Customized Options The following was designed to allow options not normally known to PostgreSQL to be declared in the posgresql.conf file and/or manipulated using the SET in a controlled manner so that add-on modules to the postgres proper (such as lanugage mappings for triggers and functions) can be configured in a unified way. custom_variable_classes (string) custom_variable_classes This variable specifies one or several classes to be used for custom variables. A custom variable is a variable not normally known to the PostgreSQL proper but used by some add on module. Aribtrary variables can be defined for each class specified here. Those variables will be treated as placeholders and have no meaning 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 the class associated with it, convert any placeholder values according to those definitions, and issue warnings for any placeholders that then remains. Here is an example what custom variables might look like: custom_variable_class = 'plr,pljava' plr.foo = '/usr/lib/R' pljava.baz = 1 plruby.var = true <== this one would generate an error This option can only be set at server start or in the postgresql.conf configuration file. 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) 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) 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) 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) If true, 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) Detection of a damaged page header normally causes PostgreSQL to report an error, aborting the current transaction. Setting zero_damaged_pages to true causes the system to instead report a warning, zero out the damaged page, and continue processing. This behavior will destroy data, namely all the rows on the damaged page. But it allows you to get past the error and retrieve rows from any undamaged pages that may be present in the table. So it is useful for recovering data if corruption has occurred due to hardware or software error. You should generally not set this true until you have given up hope of recovering data from the damaged page(s) of a table. The default setting is off, and it can only be changed by a superuser. 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_indexscan = off, enable_hashjoin = 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 A large PostgreSQL installation can quickly exhaust various operating system resource limits. (On some systems, the factory defaults are so low that you don't even need a really large installation.) If you have encountered this kind of problem, keep reading. Shared Memory and Semaphores shared memory semaphores Shared memory and semaphores are collectively referred to as System V IPC (together with message queues, which are not relevant for PostgreSQL). Almost all modern operating systems provide these features, but not all of them have them turned on or sufficiently sized by default, especially systems with BSD heritage. (For the QNX and BeOS ports, PostgreSQL provides its own replacement implementation of these facilities.) The complete lack of these facilities is usually manifested by an Illegal system call error upon server start. In that case there's nothing left to do but to reconfigure your kernel. PostgreSQL won't work without them. When PostgreSQL exceeds one of the various hard IPC limits, the server will refuse to start and should leave an instructive error message describing the problem encountered and what to do about it. (See also .) The relevant kernel parameters are named consistently across different systems; gives an overview. The methods to set them, however, vary. Suggestions for some platforms are given below. Be warned that it is often necessary to reboot your machine, and possibly even recompile the kernel, to change these settings. <systemitem class="osname">System V</> <acronym>IPC</> parameters</> <tgroup cols="3"> <thead> <row> <entry>Name</> <entry>Description</> <entry>Reasonable values</> </row> </thead> <tbody> <row> <entry><varname>SHMMAX</></> <entry>Maximum size of shared memory segment (bytes)</> <entry>250 kB + 8.2 kB * <xref linkend="guc-shared-buffers"> + 14.2 kB * <xref linkend="guc-max-connections"> up to infinity</entry> </row> <row> <entry><varname>SHMMIN</></> <entry>Minimum size of shared memory segment (bytes)</> <entry>1</> </row> <row> <entry><varname>SHMALL</></> <entry>Total amount of shared memory available (bytes or pages)</> <entry>if bytes, same as <varname>SHMMAX</varname>; if pages, <literal>ceil(SHMMAX/PAGE_SIZE)</literal></> </row> <row> <entry><varname>SHMSEG</></> <entry>Maximum number of shared memory segments per process</> <entry>only 1 segment is needed, but the default is much higher</> </row> <row> <entry><varname>SHMMNI</></> <entry>Maximum number of shared memory segments system-wide</> <entry>like <varname>SHMSEG</> plus room for other applications</> </row> <row> <entry><varname>SEMMNI</></> <entry>Maximum number of semaphore identifiers (i.e., sets)</> <entry>at least <literal>ceil(max_connections / 16)</literal></> </row> <row> <entry><varname>SEMMNS</></> <entry>Maximum number of semaphores system-wide</> <entry><literal>ceil(max_connections / 16) * 17</literal> plus room for other applications</> </row> <row> <entry><varname>SEMMSL</></> <entry>Maximum number of semaphores per set</> <entry>at least 17</> </row> <row> <entry><varname>SEMMAP</></> <entry>Number of entries in semaphore map</> <entry>see text</> </row> <row> <entry><varname>SEMVMX</></> <entry>Maximum value of semaphore</> <entry>at least 1000 (The default is often 32767, don't change unless asked to.)</> </row> </tbody> </tgroup> </table> <para> <indexterm><primary>SHMMAX</primary></indexterm> The most important shared memory parameter is <varname>SHMMAX</>, the maximum size, in bytes, of a shared memory segment. If you get an error message from <function>shmget</> like <errorname>Invalid argument</>, it is possible that this limit has been exceeded. The size of the required shared memory segment varies both with the number of requested buffers (<option>-B</> option) and the number of allowed connections (<option>-N</> option), although the former is the most significant. (You can, as a temporary solution, lower these settings to eliminate the failure.) As a rough approximation, you can estimate the required segment size by multiplying the number of buffers and the block size (8 kB by default) plus ample overhead (at least half a megabyte). Any error message you might get will contain the size of the failed allocation request. </para> <para> Less likely to cause problems is the minimum size for shared memory segments (<varname>SHMMIN</>), which should be at most approximately 256 kB for <productname>PostgreSQL</> (it is usually just 1). The maximum number of segments system-wide (<varname>SHMMNI</>) or per-process (<varname>SHMSEG</>) should not cause a problem unless your system has them set to zero. Some systems also have a limit on the total amount of shared memory in the system; see the platform-specific instructions below. </para> <para> <productname>PostgreSQL</> uses one semaphore per allowed connection (<option>-N</> option), in sets of 16. Each such set will also contain a 17th semaphore which contains a <quote>magic number</quote>, to detect collision with semaphore sets used by other applications. The maximum number of semaphores in the system is set by <varname>SEMMNS</>, which consequently must be at least as high as <varname>max_connections</> plus one extra for each 16 allowed connections (see the formula in <xref linkend="sysvipc-parameters">). The parameter <varname>SEMMNI</> determines the limit on the number of semaphore sets that can exist on the system at one time. Hence this parameter must be at least <literal>ceil(max_connections / 16)</>. Lowering the number of allowed connections is a temporary workaround for failures, which are usually confusingly worded <errorname>No space left on device</>, from the function <function>semget</>. </para> <para> In some cases it might also be necessary to increase <varname>SEMMAP</> to be at least on the order of <varname>SEMMNS</>. This parameter defines the size of the semaphore resource map, in which each contiguous block of available semaphores needs an entry. When a semaphore set is freed it is either added to an existing entry that is adjacent to the freed block or it is registered under a new map entry. If the map is full, the freed semaphores get lost (until reboot). Fragmentation of the semaphore space could over time lead to fewer available semaphores than there should be. </para> <para> The <varname>SEMMSL</> parameter, which determines how many semaphores can be in a set, must be at least 17 for <productname>PostgreSQL</>. </para> <para> Various other settings related to <quote>semaphore undo</>, such as <varname>SEMMNU</> and <varname>SEMUME</>, are not of concern for <productname>PostgreSQL</>. </para> <variablelist> <varlistentry> <term><systemitem class="osname">BSD/OS</></term> <indexterm><primary>BSD/OS</><secondary>IPC configuration</></> <listitem> <formalpara> <title>Shared Memory</> <para> By default, only 4 MB of shared memory is supported. Keep in mind that shared memory is not pageable; it is locked in RAM. To increase the amount of shared memory supported by your system, add the following to your kernel configuration file. A <varname>SHMALL</> value of 1024 represents 4 MB of shared memory. The following increases the maximum shared memory area to 32 MB: <programlisting> options "SHMALL=8192" options "SHMMAX=\(SHMALL*PAGE_SIZE\)" </programlisting> For those running 4.3 or later, you will probably need to increase <varname>KERNEL_VIRTUAL_MB</> above the default <literal>248</>. Once all changes have been made, recompile the kernel, and reboot. </para> </formalpara> <para> For those running 4.0 and earlier releases, use <command>bpatch</> to find the <varname>sysptsize</> value in the current kernel. This is computed dynamically at boot time. <screen> $ <userinput>bpatch -r sysptsize</> <computeroutput>0x9 = 9</> </screen> Next, add <varname>SYSPTSIZE</> as a hard-coded value in the kernel configuration file. Increase the value you found using <command>bpatch</>. Add 1 for every additional 4 MB of shared memory you desire. <programlisting> options "SYSPTSIZE=16" </programlisting> <varname>sysptsize</> cannot be changed by <command>sysctl</command>. </para> <formalpara> <title>Semaphores</> <para> You may need to increase the number of semaphores. By default, <productname>PostgreSQL</> allocates 34 semaphores, which is over half the default system total of 60. Set the values you want in your kernel configuration file, e.g.: <programlisting> options "SEMMNI=40" options "SEMMNS=240" </programlisting> </para> </formalpara> </listitem> </varlistentry> <varlistentry> <term><systemitem class="osname">FreeBSD</></term> <term><systemitem class="osname">NetBSD</></term> <term><systemitem class="osname">OpenBSD</></term> <indexterm><primary>FreeBSD</><secondary>IPC configuration</></> <indexterm><primary>NetBSD</><secondary>IPC configuration</></> <indexterm><primary>OpenBSD</><secondary>IPC configuration</></> <listitem> <para> The options <varname>SYSVSHM</> and <varname>SYSVSEM</> need to be enabled when the kernel is compiled. (They are by default.) The maximum size of shared memory is determined by the option <varname>SHMMAXPGS</> (in pages). The following shows an example of how to set the various parameters: <programlisting> options SYSVSHM options SHMMAXPGS=4096 options SHMSEG=256 options SYSVSEM options SEMMNI=256 options SEMMNS=512 options SEMMNU=256 options SEMMAP=256 </programlisting> (On <systemitem class="osname">NetBSD</> and <systemitem class="osname">OpenBSD</> the key word is actually <literal>option</literal> singular.) </para> <para> You might also want to configure your kernel to lock shared memory into RAM and prevent it from being paged out to swap. Use the <command>sysctl</> setting <literal>kern.ipc.shm_use_phys</>. </para> </listitem> </varlistentry> <varlistentry> <term><systemitem class="osname">HP-UX</></term> <indexterm><primary>HP-UX</><secondary>IPC configuration</></> <listitem> <para> The default settings tend to suffice for normal installations. On <productname>HP-UX</> 10, the factory default for <varname>SEMMNS</> is 128, which might be too low for larger database sites. </para> <para> <acronym>IPC</> parameters can be set in the <application>System Administration Manager</> (<acronym>SAM</>) under <menuchoice><guimenu>Kernel Configuration</><guimenuitem>Configurable Parameters</></>. Hit <guibutton>Create A New Kernel</> when you're done. </para> </listitem> </varlistentry> <varlistentry> <term><systemitem class="osname">Linux</></term> <indexterm><primary>Linux</><secondary>IPC configuration</></> <listitem> <para> The default shared memory limit (both <varname>SHMMAX</varname> and <varname>SHMALL</varname>) is 32 MB in 2.2 kernels, but it can be changed in the <filename>proc</filename> file system (without reboot). For example, to allow 128 MB: <screen> <prompt>$</prompt> <userinput>echo 134217728 >/proc/sys/kernel/shmall</userinput> <prompt>$</prompt> <userinput>echo 134217728 >/proc/sys/kernel/shmmax</userinput> </screen> You could put these commands into a script run at boot-time. </para> <para> Alternatively, you can use <command>sysctl</command>, if available, to control these parameters. Look for a file called <filename>/etc/sysctl.conf</filename> and add lines like the following to it: <programlisting> kernel.shmall = 134217728 kernel.shmmax = 134217728 </programlisting> This file is usually processed at boot time, but <command>sysctl</command> can also be called explicitly later. </para> <para> Other parameters are sufficiently sized for any application. If you want to see for yourself look in <filename>/usr/src/linux/include/asm-<replaceable>xxx</>/shmparam.h</> and <filename>/usr/src/linux/include/linux/sem.h</>. </para> </listitem> </varlistentry> <varlistentry> <term><systemitem class="osname">MacOS X</></term> <indexterm><primary>MacOS X</><secondary>IPC configuration</></> <listitem> <para> In OS X 10.2 and earlier, edit the file <filename>/System/Library/StartupItems/SystemTuning/SystemTuning</> and change the values in the following commands: <programlisting> sysctl -w kern.sysv.shmmax sysctl -w kern.sysv.shmmin sysctl -w kern.sysv.shmmni sysctl -w kern.sysv.shmseg sysctl -w kern.sysv.shmall </programlisting> In OS X 10.3, these commands have been moved to <filename>/etc/rc</> and must be edited there. </para> </listitem> </varlistentry> <varlistentry> <term><systemitem class="osname">SCO OpenServer</></term> <indexterm><primary>SCO OpenServer</><secondary>IPC configuration</></> <listitem> <para> In the default configuration, only 512 kB of shared memory per segment is allowed, which is about enough for <option>-B 24 -N 12</>. To increase the setting, first change to the directory <filename>/etc/conf/cf.d</>. To display the current value of <varname>SHMMAX</>, run <programlisting> ./configure -y SHMMAX </programlisting> To set a new value for <varname>SHMMAX</>, run <programlisting> ./configure SHMMAX=<replaceable>value</> </programlisting> where <replaceable>value</> is the new value you want to use (in bytes). After setting <varname>SHMMAX</>, rebuild the kernel: <programlisting> ./link_unix </programlisting> and reboot. </para> </listitem> </varlistentry> <varlistentry> <term><systemitem class="osname">AIX</></term> <indexterm><primary>AIX</><secondary>IPC configuration</></> <listitem> <para> At least as of version 5.1, it should not be necessary to do any special configuration for such parameters as <varname>SHMMAX</varname>, as it appears this is configured to allow all memory to be used as shared memory. That is the sort of configuration commonly used for other databases such as <application>DB/2</application>.</para> <para> It may, however, be necessary to modify the global <command>ulimit</command> information in <filename>/etc/security/limits</filename>, as the default hard limits for filesizes (<varname>fsize</varname>) and numbers of files (<varname>nofiles</varname>) may be too low. </para> </listitem> </varlistentry> <varlistentry> <term><systemitem class="osname">Solaris</></term> <indexterm><primary>Solaris</><secondary>IPC configuration</></> <listitem> <para> At least in version 2.6, the default maximum size of a shared memory segments is too low for <productname>PostgreSQL</>. The relevant settings can be changed in <filename>/etc/system</>, for example: <programlisting> set shmsys:shminfo_shmmax=0x2000000 set shmsys:shminfo_shmmin=1 set shmsys:shminfo_shmmni=256 set shmsys:shminfo_shmseg=256 set semsys:seminfo_semmap=256 set semsys:seminfo_semmni=512 set semsys:seminfo_semmns=512 set semsys:seminfo_semmsl=32 </programlisting> You need to reboot for the changes to take effect. </para> <para> See also <ulink url="http://sunsite.uakom.sk/sunworldonline/swol-09-1997/swol-09-insidesolaris.html"></> for information on shared memory under <productname>Solaris</>. </para> </listitem> </varlistentry> <varlistentry> <term><systemitem class="osname">UnixWare</></term> <indexterm><primary>UnixWare</><secondary>IPC configuration</></> <listitem> <para> On <productname>UnixWare</> 7, the maximum size for shared memory segments is 512 kB in the default configuration. This is enough for about <option>-B 24 -N 12</>. To display the current value of <varname>SHMMAX</>, run <programlisting> /etc/conf/bin/idtune -g SHMMAX </programlisting> which displays the current, default, minimum, and maximum values. To set a new value for <varname>SHMMAX</>, run <programlisting> /etc/conf/bin/idtune SHMMAX <replaceable>value</> </programlisting> where <replaceable>value</> is the new value you want to use (in bytes). After setting <varname>SHMMAX</>, rebuild the kernel: <programlisting> /etc/conf/bin/idbuild -B </programlisting> and reboot. </para> </listitem> </varlistentry> </variablelist> </sect2> <sect2> <title>Resource Limits Unix-like operating systems enforce various kinds of resource limits that might interfere with the operation of your PostgreSQL server. Of particular importance are limits on the number of processes per user, the number of open files per process, and the amount of memory available to each process. Each of these have a hard and a soft limit. The soft limit is what actually counts but it can be changed by the user up to the hard limit. The hard limit can only be changed by the root user. The system call setrlimit is responsible for setting these parameters. The shell's built-in command ulimit (Bourne shells) or limit (csh) is used to control the resource limits from the command line. On BSD-derived systems the file /etc/login.conf controls the various resource limits set during login. See the operating system documentation for details. The relevant parameters are maxproc, openfiles, and datasize. For example: default:\ ... :datasize-cur=256M:\ :maxproc-cur=256:\ :openfiles-cur=256:\ ... (-cur is the soft limit. Append -max to set the hard limit.) Kernels can also have system-wide limits on some resources. On Linux /proc/sys/fs/file-max determines the maximum number of open files that the kernel will support. It can be changed by writing a different number into the file or by adding an assignment in /etc/sysctl.conf. The maximum limit of files per process is fixed at the time the kernel is compiled; see /usr/src/linux/Documentation/proc.txt for more information. The PostgreSQL server uses one process per connection so you should provide for at least as many processes as allowed connections, in addition to what you need for the rest of your system. This is usually not a problem but if you run several servers on one machine things might get tight. The factory default limit on open files is often set to socially friendly values that allow many users to coexist on a machine without using an inappropriate fraction of the system resources. If you run many servers on a machine this is perhaps what you want, but on dedicated servers you may want to raise this limit. On the other side of the coin, some systems allow individual processes to open large numbers of files; if more than a few processes do so then the system-wide limit can easily be exceeded. If you find this happening, and you do not want to alter the system-wide limit, you can set PostgreSQL's configuration parameter to limit the consumption of open files. Linux Memory Overcommit In Linux 2.4 and later, the default virtual memory behavior is not optimal for PostgreSQL. Because of the way that the kernel implements memory overcommit, the kernel may terminate the PostgreSQL server (the postmaster process) if the memory demands of another process cause the system to run out of virtual memory. If this happens, you will see a kernel message that looks like this (consult your system documentation and configuration on where to look for such a message): Out of Memory: Killed process 12345 (postmaster). This indicates that the postmaster process has been terminated due to memory pressure. Although existing database connections will continue to function normally, no new connections will be accepted. To recover, PostgreSQL will need to be restarted. One way to avoid this problem is to run PostgreSQL on a machine where you can be sure that other processes will not run the machine out of memory. On Linux 2.6 and later, a better solution is to modify the kernel's behavior so that it will not overcommit memory. This is done by selecting strict overcommit mode via sysctl: sysctl -w vm.overcommit_memory=2 or placing an equivalent entry in /etc/sysctl.conf. You may also wish to modify the related setting vm.overcommit_ratio. For details see the kernel documentation file Documentation/vm/overcommit-accounting. Some vendors' Linux 2.4 kernels are reported to have early versions of the 2.6 overcommit sysctl. However, setting vm.overcommit_memory to 2 on a kernel that does not have the relevant code will make things worse not better. It is recommended that you inspect the actual kernel source code (see the function vm_enough_memory in the file mm/mmap.c) to verify what is supported in your copy before you try this in a 2.4 installation. The presence of the overcommit-accounting documentation file should not be taken as evidence that the feature is there. If in any doubt, consult a kernel expert or your kernel vendor. Shutting Down the Server shutdown There are several ways to shut down the database server. You control the type of shutdown by sending different signals to the postmaster process. SIGTERMSIGTERM After receiving SIGTERM, the server disallows new connections, but lets existing sessions end their work normally. It shuts down only after all of the sessions terminate normally. This is the Smart Shutdown. SIGINTSIGINT The server disallows new connections and sends all existing server processes SIGTERM, which will cause them to abort their current transactions and exit promptly. It then waits for the server processes to exit and finally shuts down. This is the Fast Shutdown. SIGQUITSIGQUIT This is the Immediate Shutdown, which will cause the postmaster process to send a SIGQUIT to all child processes and exit immediately (without properly shutting itself down). The child processes likewise exit immediately upon receiving SIGQUIT. This will lead to recovery (by replaying the WAL log) upon next start-up. This is recommended only in emergencies. It is best not to use SIGKILL to shut down the server. This will prevent the server from releasing shared memory and semaphores, which may then have to be done by manually. The PID of the postmaster process can be found using the ps program, or from the file postmaster.pid in the data directory. So for example, to do a fast shutdown: $ kill -INT `head -1 /usr/local/pgsql/data/postmaster.pid` The program pg_ctl is a shell script that provides a more convenient interface for shutting down the server. Secure TCP/IP Connections with SSL SSL PostgreSQL has native support for using SSL connections to encrypt client/server communications for increased security. This requires that OpenSSL is installed on both client and server systems and that support in PostgreSQL is enabled at build time (see ). With SSL support compiled in, the PostgreSQL server can be started with SSL enabled by setting the parameter to on in postgresql.conf. When starting in SSL mode, the server will look for the files server.key and server.crt in the data directory, which should contain the server private key and certificate, respectively. These files must be set up correctly before an SSL-enabled server can start. If the private key is protected with a passphrase, the server will prompt for the passphrase and will not start until it has been entered. The server will listen for both standard and SSL connections on the same TCP port, and will negotiate with any connecting client on whether to use SSL. See about how to force the server to require use of SSL for certain connections. For details on how to create your server private key and certificate, refer to the OpenSSL documentation. A simple self-signed certificate can be used to get started for testing, but a certificate signed by a certificate authority (CA) (either one of the global CAs or a local one) should be used in production so the client can verify the server's identity. To create a quick self-signed certificate, use the following OpenSSL command: openssl req -new -text -out server.req Fill out the information that openssl asks for. Make sure that you enter the local host name as Common Name; the challenge password can be left blank. The program will generate a key that is passphrase protected; it will not accept a passphrase that is less than four characters long. To remove the passphrase (as you must if you want automatic start-up of the server), run the commands openssl rsa -in privkey.pem -out server.key rm privkey.pem Enter the old passphrase to unlock the existing key. Now do openssl req -x509 -in server.req -text -key server.key -out server.crt chmod og-rwx server.key to turn the certificate into a self-signed certificate and to copy the key and certificate to where the server will look for them. Secure TCP/IP Connections with <application>SSH</application> Tunnels ssh One can use SSH to encrypt the network connection between clients and a PostgreSQL server. Done properly, this provides an adequately secure network connection. First make sure that an SSH server is running properly on the same machine as the PostgreSQL server and that you can log in using ssh as some user. Then you can establish a secure tunnel with a command like this from the client machine: ssh -L 3333:foo.com:5432 joe@foo.com The first number in the argument, 3333, is the port number of your end of the tunnel; it can be chosen freely. The second number, 5432, is the remote end of the tunnel: the port number your server is using. The name or the address in between the port numbers is the host with the database server you are going to connect to. In order to connect to the database server using this tunnel, you connect to port 3333 on the local machine: psql -h localhost -p 3333 template1 To the database server it will then look as though you are really user joe@foo.com and it will use whatever authentication procedure was set up for this user. In order for the tunnel setup to succeed you must be allowed to connect via ssh as joe@foo.com, just as if you had attempted to use ssh to set up a terminal session. Several other applications exist that can provide secure tunnels using a procedure similar in concept to the one just described.