Server Runtime 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. 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, 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. PGDATA As an alternative to the option, you can set the environment variable 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 pg_hba.conf authentication method of trust allows any local user to connect to the database and even become the database superuser. If you don't trust other local users, we recommend you use initdb's or option to assign a password to the database superuser. After initdb, modify pg_hba.conf 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. LC_COLLATE One surprise you might encounter while running initdb is a notice similar to this: WARNING: Initializing database with en_US collation order. This locale setting will prevent use of index optimization for LIKE and regexp searches. If you are concerned about speed of such queries, you may wish to set LC_COLLATE to "C" and re-initdb. For more information see the Administrator's Guide. This is intended to warn you that the currently selected locale will cause indexes to be sorted in an order that prevents them from being used for LIKE and regular-expression searches. If you need good performance in such searches, you should set your current locale to C and re-run initdb. On most systems, setting the current locale is done by changing the value of the environment variable LC_ALL or LANG. 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 postmaster Before anyone can access the database, you must start the database server. The database server is called 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 in the environment variable PGDATA. If neither of these succeed, it will fail. To start the postmaster in the background, use the usual shell syntax: $ postmaster -D /usr/local/pgsql/data > logfile 2>&1 & It is an 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.) TCP/IP The postmaster also takes a number of other command line options. For more information, see the reference page and below. In particular, in order for the server to accept TCP/IP connections (rather than just Unix domain socket ones), you must specify the option. pg_ctl This shell syntax can get tedious quickly. Therefore the shell script wrapper pg_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. Auto-start scripts are operating-system specific. There are a few distributed with PostgreSQL in the /contrib/start-scripts directory. This may 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. (Always replace these with the proper installation directory and the user name.) For FreeBSD, look at the file contrib/start-scripts/freebsd in the PostgreSQL source distribution. FreeBSD On OpenBSD, add the following lines to the file /etc/rc.local: OpenBSD 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 Linux /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. NetBSD On Solaris, create a file called /etc/init.d/postgresql which should contain the following line: Solaris 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 in the file postmaster.pid in the data directory. This is used to prevent multiple postmasters running in the same data directory, and can also be used for shutting down the postmaster. Server Start-up Failures There are several common reasons the postmaster might fail to start. Check the postmaster's log file, or start it by hand (without redirecting standard output or standard error) and see what error messages appear. Some of the error messages are self-explanatory, but some are not, as shown below: FATAL: StreamServerPort: bind() failed: Address already in use Is another postmaster already running on that port? 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 -i -p 666 FATAL: StreamServerPort: bind() failed: Permission denied Is another postmaster already running on that port? A message like: IpcMemoryCreate: shmget(key=5440001, size=83918612, 01600) failed: Invalid argument FATAL 1: ShmemCreate: cannot create region probably means your kernel's limit on the size of shared memory is smaller than the buffer area PostgreSQL is trying to create (83918612 bytes in this example). Or it could mean that you don't have System-V-style shared memory support configured into your kernel at all. As a temporary workaround, you can try starting the postmaster 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 see this message when trying to start multiple postmasters on the same machine if their total space requested exceeds the kernel limit. An error like: IpcSemaphoreCreate: semget(key=5440026, num=16, 01600) failed: No space left on device 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 postmaster with a reduced number of backend processes ( switch), but you'll eventually want to increase the kernel limit. If you get an illegal system call error, it is likely 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 the option to allow the postmaster to accept TCP/IP connections. Alternatively, you'll get this when attempting Unix-socket communication to a local postmaster: psql: could not connect to server: Connection refused 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 postmaster 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 postmaster 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 server There are a lot of configuration parameters that affect the behavior of the database system. Here we describe how to set them and the following subsections will discuss each 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 options is to edit the file postgresql.conf in the data directory. (A default file is installed there.) An example of what this file might look like is: # This is a comment log_connections = yes syslog = 2 As you see, options are one per line. The equal sign between name and value is optional. Whitespace is insignificant and blank lines are ignored. Hash marks (#) introduce comments anywhere. SIGHUP The configuration file is reread whenever the postmaster 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 backend processes so that existing sessions also get the new value. Alternatively, you can send the signal to a single backend process directly. A second way to set these configuration parameters is to give them as a command line option to the postmaster, such as: postmaster -c log_connections=yes -c syslog=2 which would have the same effect as the previous example. Command-line options override any conflicting settings in postgresql.conf. Occasionally it is also useful to give a command line option to one particular backend session only. The environment variable PGOPTIONS can be used for this purpose on the client side: env PGOPTIONS='-c geqo=off' psql (This works for any client application, not just psql.) Note that this won't work for options that are fixed when the server is started, such as the port number. Some options can be changed in individual SQL sessions with the SET command, for example: => SET ENABLE_SEQSCAN TO OFF; See the SQL command language reference for details on the syntax. Furthermore, it is possible to assign a set of option settings to a user or a database. Whenever a session is started, the default settings for the user and database involved are loaded. The commands ALTER DATABASE and ALTER USER, respectively, are used to configure these. Planner and Optimizer Tuning CPU_INDEX_TUPLE_COST (floating point) Sets the query optimizer's estimate of the cost of processing each index tuple during an index scan. This is measured as a fraction of the cost of a sequential page fetch. CPU_OPERATOR_COST (floating point) Sets the optimizer's estimate of the cost of processing each operator in a WHERE clause. This is measured as a fraction of the cost of a sequential page fetch. CPU_TUPLE_COST (floating point) Sets the query optimizer's estimate of the cost of processing each tuple during a query. This is measured as a fraction of the cost of a sequential page fetch. EFFECTIVE_CACHE_SIZE (floating point) Sets the optimizer's assumption about the effective size of the disk cache (that is, the portion of the kernel's disk cache that will be used for PostgreSQL data files). This is measured in disk pages, which are normally 8 kB each. 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 to 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. 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. See also the various other GEQO_ settings. GEQO_EFFORT (integer) GEQO_GENERATIONS (integer) GEQO_POOL_SIZE (integer) GEQO_RANDOM_SEED (integer) GEQO_SELECTION_BIAS (floating point) Various tuning parameters for the genetic query optimization algorithm: The pool size is the number of individuals in one population. Valid values are between 128 and 1024. If it is set to 0 (the default) a pool size of 2^(QS+1), where QS is the number of FROM items in the query, is taken. The effort is used to calculate a default for generations. Valid values are between 1 and 80, 40 being the default. Generations specifies the number of iterations in the algorithm. The number must be a positive integer. If 0 is specified then Effort * Log2(PoolSize) is used. The run time of the algorithm is roughly proportional to the sum of pool size and generations. The selection bias is the selective pressure within the population. Values can be from 1.50 to 2.00; the latter is the default. The random seed can be set to get reproducible results from the algorithm. If it is set to -1 then the algorithm behaves non-deterministically. GEQO_THRESHOLD (integer) Use genetic query optimization to plan queries with at least this many FROM items involved. (Note that a JOIN construct counts as only one FROM item.) The default is 11. For simpler queries it is usually best to use the deterministic, exhaustive planner. This parameter also controls how hard the optimizer will try to merge subquery FROM clauses into the upper query. KSQO (boolean) The Key Set Query Optimizer (KSQO) causes the query planner to convert queries whose WHERE clause contains many OR'ed AND clauses (such as WHERE (a=1 AND b=2) OR (a=2 AND b=3) ...) into a union query. This method can be faster than the default implementation, but it doesn't necessarily give exactly the same results, since UNION implicitly adds a SELECT DISTINCT clause to eliminate identical output rows. KSQO is commonly used when working with products like Microsoft Access, which tend to generate queries of this form. The KSQO algorithm used to be absolutely essential for queries with many OR'ed AND clauses, but in PostgreSQL 7.0 and later the standard planner handles these queries fairly successfully; hence the default is off. RANDOM_PAGE_COST (floating point) Sets the query optimizer'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. Unfortunately, there is no well-defined method for determining ideal values for the family of COST variables that were just described. You are encouraged to experiment and share your findings. Logging and Debugging SERVER_MIN_MESSAGES (string) This controls how much detail is written to the server logs. The default is NOTICE. Valid values are DEBUG5, DEBUG4, DEBUG3, DEBUG2, DEBUG1, INFO, NOTICE, WARNING, ERROR, LOG, FATAL, and PANIC. Later values send less detail to the logs. LOG has a different precedence here than in CLIENT_MIN_MESSAGES. CLIENT_MIN_MESSAGES (string) This controls how much detail is written to the client. The default is NOTICE. Valid values are DEBUG5, DEBUG4, DEBUG3, DEBUG2, DEBUG1, LOG, NOTICE, WARNING, and ERROR. Later values send less information to the user. LOG has a different precedence here than in SERVER_MIN_MESSAGES. 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 (see the configure option --enable-cassert). Note that DEBUG_ASSERTIONS defaults to on if PostgreSQL has been built this way. DEBUG_PRINT_QUERY (boolean) DEBUG_PRINT_PARSE (boolean) DEBUG_PRINT_REWRITTEN (boolean) DEBUG_PRINT_PLAN (boolean) DEBUG_PRETTY_PRINT (boolean) These flags enable various debugging output to be sent to the server log. For each executed query, prints either the query text, the resulting parse tree, the query rewriter output, or the execution plan. indents these displays to produce a more readable but much longer output format. HOSTNAME_LOOKUP (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. 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_PID (boolean) Prefixes each server log message with the process ID of the backend process. This is useful to sort out which messages pertain to which connection. The default is off. LOG_TIMESTAMP (boolean) Prefixes each server log message with a time stamp. The default is off. SHOW_QUERY_STATS (boolean) SHOW_PARSER_STATS (boolean) SHOW_PLANNER_STATS (boolean) SHOW_EXECUTOR_STATS (boolean) For each query, write performance statistics of the respective module to the server log. This is a crude profiling instrument. SHOW_SOURCE_PORT (boolean) Shows the outgoing port number of the connecting host in the connection log messages. You could trace back the port number to find out what user initiated the connection. Other than that, it's pretty useless and therefore off by default. This option can only be set at server start. STATS_COMMAND_STRING (boolean) STATS_BLOCK_LEVEL (boolean) STATS_ROW_LEVEL (boolean) These flags determine what information backends send to the statistics collector process: current commands, block-level activity statistics, or row-level activity statistics. All default to off. Enabling statistics collection costs a small amount of time per query, but is invaluable for debugging and performance tuning. 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. 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. SYSLOG (integer) PostgreSQL allows the use of syslog for logging. If this option is set to 1, messages go both to syslog and the standard output. A setting of 2 sends output only to syslog. (Some messages will still go to the standard output/error.) The default is 0, which means syslog is off. This option must be set at server start. To use syslog, the build of PostgreSQL must be configured with the option. SYSLOG_FACILITY (string) This option determines the syslog facility to be used when syslog is enabled. You may choose from LOCAL0, LOCAL1, LOCAL2, LOCAL3, LOCAL4, LOCAL5, LOCAL6, LOCAL7; the default is LOCAL0. See also the documentation of your system's syslog. SYSLOG_IDENT (string) If logging to syslog is enabled, this option determines the program name used to identify PostgreSQL messages in syslog log messages. The default is postgres. TRACE_NOTIFY (boolean) Generates a great amount of debugging output for the LISTEN and NOTIFY commands. General operation AUSTRALIAN_TIMEZONES (bool) Australian time zones If set to true, CST, EST, and SAT are interpreted as Australian time zones rather than as North American Central/Eastern time zones and Saturday. The default is false. AUTHENTICATION_TIMEOUT (integer) timeoutauthentication 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. deadlock timeout 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 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 the lock will be released before the waiter decides to check for deadlock. This option can only be set at server start. transaction isolation level DEFAULT_TRANSACTION_ISOLATION (string) Each SQL transaction has an isolation level, which can be either read committed or serializable. This parameter controls the default isolation level of each new transaction. The default is read committed. Consult the PostgreSQL User's Guide and the command SET TRANSACTION for more information. 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 colon-separated list of absolute directory names. If a directory name starts with the special value $libdir, the compiled-in PostgreSQL package library directory is substituted. This where the modules provided by the PostgreSQL distribution are installed. (Use pg_config --pkglibdir to print the name of this directory.) For example: dynamic_library_path = '/usr/local/lib/postgresql:/home/my_project/lib:$libdir' The default value for this parameter is $libdir. If the value is set to an empty string, the automatic path search is turned off. This parameter can be changed at run time by superusers, but a setting done that way will only persist until the end of the client connection, so this method should be reserved for development purposes. The recommended way to set this parameter is in the postgresql.conf configuration file. fsync FSYNC (boolean) If this option is on, the PostgreSQL backend will use the fsync() system call in several places to make sure that updates are physically written to disk. This insures that a database installation 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, this operation does slow down PostgreSQL because at transaction commit it has wait for the operating system to flush the write-ahead log. Without fsync, the operating system is allowed to do its best in buffering, sorting, and delaying writes, which can considerably increase 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. For the above reasons, some administrators always leave it off, some turn it off only for bulk loads, where there is a clear restart point if something goes wrong, and some leave it on just to be on the safe side. Because it is always safe, the default is on. If you trust your operating system, your hardware, and your utility company (or better your UPS), you might want to disable fsync. It should be noted that the performance penalty of doing fsyncs is considerably less in PostgreSQL version 7.1 and later. If you previously suppressed fsyncs for performance reasons, you may wish to reconsider your choice. This option can only be set at server start or in the postgresql.conf file. KRB_SERVER_KEYFILE (string) Sets the location of the Kerberos server key file. See for details. MAX_CONNECTIONS (integer) Determines the maximum number of concurrent connections to the database server. The default is 32 (unless altered while building the server). This parameter can only be set at server start. MAX_EXPR_DEPTH (integer) Sets the maximum expression nesting depth of the parser. The default value is high enough for any normal query, but you can raise it if needed. (But if you raise it too high, you run the risk of backend crashes due to stack overflow.) MAX_FILES_PER_PROCESS (integer) Sets the maximum number of simultaneously open files in each server subprocess. The default is 1000. The limit actually used by the code is the smaller of this setting and the result of sysconf(_SC_OPEN_MAX). Therefore, on systems where sysconf returns a reasonable limit, you don't need to worry about this setting. But on some platforms (notably, most BSD systems), sysconf returns a value that is much larger 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 or in the postgresql.conf configuration file; if changed in the configuration file, it only affects subsequently-started server subprocesses. MAX_FSM_RELATIONS (integer) Sets the maximum number of relations (tables) for which free space will be tracked in the shared free-space map. The default is 100. This option can only be set at server start. MAX_FSM_PAGES (integer) Sets the maximum number of disk pages for which free space will be tracked in the shared free-space map. The default is 10000. This option can only be set at server start. 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, which 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. PASSWORD_ENCRYPTION (boolean) When a password is specified in CREATE USER or ALTER USER without writing either ENCRYPTED or UNENCRYPTED, this flag determines whether the password is to be encrypted. The default is off (do not encrypt the password), but this choice may change in a future release. PORT (integer) port The TCP port the server listens on; 5432 by default. This option can only be set at server start. SHARED_BUFFERS (integer) Sets the number of shared memory buffers used by the database server. The default is 64. Each buffer is typically 8192 bytes. This option can only be set at server start. SILENT_MODE (bool) Runs postmaster silently. If this option is set, the postmaster will automatically run in background and any controlling ttys are disassociated, thus no messages are written to standard output or standard error (same effect as postmaster's -S option). Unless some logging system such as syslog is enabled, using this option is discouraged since it makes it impossible to see error messages. SORT_MEM (integer) Specifies the amount of memory to be used by internal sorts and hashes before switching to temporary disk files. The value is specified in kilobytes, and defaults to 512 kilobytes. Note that for a complex query, several sorts and/or hashes might be running in parallel, and each one will be allowed to use as much memory as this value specifies before it starts to put data into temporary files. Also, each running backend could be doing one or more sorts simultaneously, so the total memory used could be many times the value of SORT_MEM. SQL_INHERITANCE (bool) 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 keyword to exclude subtables. See the SQL language reference and the User's Guide for more information about inheritance. SSL SSL (boolean) Enables SSL connections. Please read before using this. The default is off. TCPIP_SOCKET (boolean) If this is true, then the server will accept TCP/IP connections. Otherwise only local Unix domain socket connections are accepted. It is off by default. This option can only be set at server start. 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 NULLs, 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 NULL (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, 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 the User's Guide for related information. UNIX_SOCKET_DIRECTORY (string) Specifies the directory of the Unix-domain socket on which the postmaster is to listen for connections from client applications. The default is normally /tmp, but can be changed at build time. 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 postmaster.) In combination with the option this can be used as an additional access control mechanism for this socket type. By default this is the empty string, which uses the default group for the current user. This option can 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 ) and 0700 (only user). (Note that actually for a Unix 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. VACUUM_MEM (integer) Specifies the maximum amount of memory to be used by VACUUM to keep track of to-be-reclaimed tuples. The value is specified in kilobytes, and defaults to 8192 kilobytes. Larger settings may improve the speed of vacuuming large tables that have many deleted tuples. VIRTUAL_HOST (string) Specifies the TCP/IP host name or address on which the postmaster is to listen for connections from client applications. Defaults to listening on all configured addresses (including localhost). WAL See also for details on WAL tuning. CHECKPOINT_SEGMENTS (integer) Maximum distance between automatic WAL checkpoints, in log file segments (each segment is normally 16 megabytes). 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. This option can only be set at server start or in the postgresql.conf file. 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 backend has written its commit record. 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. WAL_BUFFERS (integer) Number of disk-page buffers in shared memory for WAL logging. This option can only be set at server start. WAL_DEBUG (integer) If non-zero, turn on WAL-related debugging output on standard error. WAL_FILES (integer) Number of log files that are created in advance at checkpoint time. 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), or 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. Short options For convenience there are also single letter option switches available for many parameters. They are described in the following table. Short option key Short option Equivalent Remark shared_buffers = x server_min_messages = DEBUGx fsync = off virtual_host = x tcpip_socket = on unix_socket_directory = x ssl = on max_connections = x port = x , , , , , enable_indexscan=off, enable_hashjoin=off, enable_mergejoin=off, enable_nestloop=off, enable_seqscan=off, enable_tidscan=off * sort_mem = x * show_query_stats = on * , , show_parser_stats=on, show_planner_stats=on, show_executor_stats=on *
For historical reasons, options marked * must be passed to the individual backend process via the postmaster option, for example, $ postmaster -o '-S 1024 -s' or via PGOPTIONS from the client side, as explained above.
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 postmaster 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 postmaster 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>250kB + 8.2kB * <varname>shared_buffers</> + 14.2kB * <varname>max_connections</> or 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><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> + room for other applications</> </row> <row> <entry><varname>SEMMSL</></> <entry>Maximum number of semaphores per set</> <entry>>= 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>>= 255 (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 the connection setting 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 <quote><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> <para> <variablelist> <varlistentry> <term><systemitem class="osname">BSD/OS</></term> <indexterm><primary>BSD/OS</></> <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 number of shared buffers supported by the postmaster, add the following to your kernel configuration file. A <varname>SHMALL</> value of 1024 represents 4MB of shared memory. The following increases the maximum shared memory area to 32 MB: <programlisting> options "SHMALL=8192" options "SHMMAX=\(SHMALL*PAGE_SIZE\)" </programlisting> </para> </formalpara> <para> For those running 4.1 or later, just make the above changes, recompile the kernel, and reboot. For those running earlier releases, use <application>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 <application>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. </para> </formalpara> <para> Set the values you want in your kernel configuration file, e.g.: <programlisting> options "SEMMNI=40" options "SEMMNS=240" options "SEMUME=40" options "SEMMNU=120" </programlisting> </para> </listitem> </varlistentry> <varlistentry> <term><systemitem class="osname">FreeBSD</></term> <term><systemitem class="osname">NetBSD</></term> <term><systemitem class="osname">OpenBSD</></term> <indexterm><primary>FreeBSD</></> <indexterm><primary>NetBSD</></> <indexterm><primary>OpenBSD</></> <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 may also want to use the <application>sysctl</> setting to lock shared memory into RAM and prevent it from being paged out to swap. </para> </listitem> </varlistentry> <varlistentry> <term><systemitem class="osname">HP-UX</></term> <indexterm><primary>HP-UX</></> <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</></> <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 <citerefentry><refentrytitle>sysctl</refentrytitle> <manvolnum>8</manvolnum></citerefentry>, 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 <application>sysctl</application> 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</>/shmpara m.h</> and <filename>/usr/src/linux/include/linux/sem.h</>. </para> </listitem> </varlistentry> <varlistentry> <term><systemitem class="osname">SCO OpenServer</></term> <indexterm><primary>SCO OpenServer</></> <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 directory to <filename>/etc/conf/cf.d</>. To display the current value of <varname>SHMMAX</>, in bytes, 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">Solaris</></term> <indexterm><primary>Solaris</></> <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://www.sunworld.com/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</></> <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, in bytes. 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> </para> </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 login.conf 5 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 don't want to alter the system-wide limit, you can set PostgreSQL's max_files_per_process configuration parameter to limit the consumption of open files. Shutting down the server There are several ways to shut down the database server. You control the type of shutdown by sending different signals to the server process. SIGTERM After receiving SIGTERM, the postmaster disallows new connections, but lets existing backends end their work normally. It shuts down only after all of the backends terminate normally. This is Smart Shutdown. SIGINT The postmaster disallows new connections and sends all existing backends SIGTERM, which will cause them to abort their current transactions and exit promptly. It then waits for the backends to exit and finally shuts down. This is Fast Shutdown. SIGQUIT This is Immediate Shutdown, which will cause the postmaster to send a SIGQUIT to all backends and exit immediately (without properly shutting itself down). The backends 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 postmaster. This will prevent the postmaster 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 postmaster. 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 OpenSSL be installed on both client and server systems and support enabled at build time (see ). With SSL support compiled in, the PostgreSQL server can be started with the argument The server will listen for both standard and SSL connections on the same TCP/IP port, and will negotiate with any connecting client on whether to use SSL. See about how to force the server to only 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 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 cert.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 script will generate a key that is passphrase protected; it will not accept a pass phrase 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 cert.pem Enter the old passphrase to unlock the existing key. Now do openssl req -x509 -in cert.req -text -key cert.pem -out cert.cert cp cert.pem $PGDATA/server.key cp cert.cert $PGDATA/server.crt 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 Acknowledgement Idea taken from an email by Gene Selkov, Jr. (selkovjr@mcs.anl.gov) written on 1999-09-08 in response to a question from Eric Marsden. One can use ssh to encrypt the network connection between clients and a PostgreSQL server. Done properly, this should lead to an adequately secure network connection. First make sure that an ssh server is running properly on the same machine as PostgreSQL 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 products exist that can provide secure tunnels using a procedure similar in concept to the one just described.