Server Runtime Environment This chapter discusses how to set up and run the database server and the interactions with the operating system. The Postgres user account As with any other server daemon that is connected to the world at large, it is advisable to run Postgres under a separate user account. This user account should only own the data itself that is being managed by the server, and should not be shared with other daemons. (Thus, using the user nobody is a bad idea.) It is not advisable to install the executables as owned by this user account because that runs the risk of user-defined functions gone astray or any other exploits compromising the executable programs. To add a user account to your system, look for a command useradd or adduser. The user name postgres is often used but by no means required. Creating a database cluster Before you can do anything, you must initialize a database storage area on disk. We call this a database cluster. (SQL speaks of a catalog cluster instead.) A database cluster is a collection of databases that will be accessible through a single instance of a running database server. After initialization, a database cluster will contain one database named template1. As the name suggests, this will be used as a template for any subsequently created database; 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 being logged in to the Postgres user account, which is described in the previous section. 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 won't have the permission to do so (if you followed our advice and created an unprivileged account). In that case you can create the directory yourself (as root) and transfer ownership of it or grant write access to it. Here is how this might work: 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 belongs to an already initialized installation. Because the data directory contains all the data stored in the database it is essential that it be well secured from unauthorized access. initdb therefore revokes access permissions from everyone but the Postgres user account. Starting the database server 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 work on. This is done with the option. Thus, the simplest way to start the server is, for example, > postmaster -D /usr/local/pgsql/data which will leave the server running in the foreground. This must again be done while logged in to the Postgres user account. Without a , the server will try to use the data directory in the environment variable PGDATA; if neither of these works 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 extremely good idea to keep the server output around somewhere, as indicated here. It will help both for auditing purposes and to diagnose problems. The postmaster also takes a number of other command line options. For more information see the reference page and below under runtime configuration. In particular, in order for the postmaster to accept TCP/IP connections (rather than just Unix domain socket ones), you must also specify the option. Normally, you will want to start the database server when the computer boots up. This is not required; the PostgreSQL server can be run successfully from non-privileged accounts without root intervention. Different systems have different conventions for starting up daemons at boot time, so you are advised to familiarize yourself with them. Many systems have a file /etc/rc.local or /etc/rc.d/rc.local which is almost certainly no bad place to put such a command. Whatever you do, postmaster must be run by the Postgres user account and not by root or any other user. Therefore you probably always want to form your command lines along the lines of su -c '...' postgres, for example: nohup su -c 'postmaster -D /usr/local/pgsql/data > server.log 2>&1' postgres & (using the program nohup to prevent the server from dying when you log out). Here are a few more operating system specific suggestions. Edit the file rc.local on NetBSD or file rc2.d on Solaris to contain the following single line: su postgres -c "/usr/local/pgsql/bin/postmaster -D /usr/local/pgsql/data" On FreeBSD edit /usr/local/etc/rc.d/pgsql.sh to contain the following lines and make it chmod 755 and chown root:bin. #!/bin/sh [ -x /usr/local/pgsql/bin/postmaster ] && { su -l pgsql -c 'exec /usr/local/pgsql/bin/postmaster -D/usr/local/pgsql/data -S -o -F > /usr/local/pgsql/errlog' & echo -n ' pgsql' } You may put the line breaks as shown above. The shell is smart enough to keep parsing beyond end-of-line if there is an expression unfinished. The exec saves one layer of shell under the postmaster process so the parent is init. On RedHat Linux add a file /etc/rc.d/init.d/postgres.init which is based on the example in contrib/linux/. Then make a softlink to this file from /etc/rc.d/rc5.d/S98postgres.init. While the postmaster is running, it's PID is in the file postmaster.pid in the data directory. This is used as in interlock against multiple running postmaster on the same data directory and can also be used for shutting down the postmaster. The shell script wrapper pg_ctl that comes with Postgres can also be used to control starting (and stopping!) of the database server in intelligent fashion. Server Start-up Failures There are several common reasons for the postmaster to fail to start up. Check the postmaster's log file, or start it by hand (without redirecting standard output or standard error) to see what complaint messages appear. Some of the possible error messages are reasonably self-explanatory, but here are some that are not. FATAL: StreamServerPort: bind() failed: Address already in use Is another postmaster already running on that port? This usually means just what it suggests: you accidentally started a second 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 wording, 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 that your kernel's limit on the size of shared memory areas is smaller than the buffer area that Postgres 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, however. You may see this message when trying to start multiple postmasters on the same machine, if their total space requests exceed the kernel limit. An error like IpcSemaphoreCreate: semget(key=5440026, num=16, 01600) failed: No space left on device does not mean that you've run out of disk space; it means that your kernel's limit on the number of System V semaphores is smaller than the number Postgres 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, then it is likely that shared memory or semaphores are not supported at all in your kernel. In that case your only option is to re-configure the kernel to turn on these features. Details about configuring System V IPC facilities are given in . Client Connection Problems Although the possible error conditions on the client side are both virtually infinite 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. connectDB() -- connect() failed: Connection refused Is the postmaster running (with -i) at 'server.joe.com' and accepting connections on TCP/IP 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 to the postmaster to allow TCP/IP connections. Alternatively, you'll get this when attempting Unix-socket communication to a local postmaster: connectDB() -- connect() failed: No such file or directory Is the postmaster running at 'localhost' and accepting connections on Unix socket '5432'? The last line is useful in verifying that the client is trying to connect where it is supposed to. 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 particularly 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 There are a lot of configuration parameters that affect the behavior of the database system in some way or other. Here we describe how to set them and the following subsections will discuss each of them. All parameter names are case-insensitive. Every parameter takes a value of one of the four types boolean, integer, floating point, string as described below. 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 create a file postgresql.conf in the data directory (e.g., /usr/local/pgsql/data). An example of what this file could 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. White space is insignificant, blank lines are ignored. Hash marks (#) introduce comments anywhere. The configuration file is reread whenever the postmaster receives a SIGHUP signal. This signal is also propagated to all running backend processes, so that running sessions get the new default. Alternatively, you can send the signal to only one 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. 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 necessarily fixed once the server is started, such as the port number. Finally, 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. 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 Postgres data files). This is measured in disk pages, which are normally 8kB apiece. ENABLE_HASHJOIN (boolean) Enables or disables the query planner's use of hash-join plan types. The default is on. This is mostly useful to debug the query planner. ENABLE_INDEXSCAN (boolean) Enables or disables the query planner's use of index scan plan types. The default is on. This is mostly useful to debug 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 mostly useful to debug 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 is any other method available. The default is on. This is mostly useful to debug the query planner. 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 is any other method available. The default is on. This is mostly useful to debug 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 is any other method available. The default is on. This is mostly useful to debug 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 mostly useful to debug the query planner. GEQO (boolean) Enables or disables genetic query optimization, which is an algorithm that attempts to do query planning without exhaustive search. 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 relations 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 reproduceable results from the algorithm. If it is set to -1 then the algorithm behaves non-deterministically. GEQO_RELS (integer) Only use genetic query optimization for queries with at least this many relations involved. The default is 11. For less relations it is probably more efficient to use the deterministic, exhaustive planner. 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 Postgres 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 of 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 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 Postgres is built (see the configure option --enable-cassert). Note that DEBUG_ASSERTIONS defaults to ON if Postgres has been built this way. DEBUG_LEVEL (integer) The higher this value is set, the more debugging output of various sorts is generated in the server log during operation. This option is 0 by default, which means no debugging output. Values up to about 4 currently make sense. DEBUG_PRINT_PARSE (boolean) DEBUG_PRINT_PLAN (boolean) DEBUG_PRINT_REWRITTEN (boolean) DEBUG_PRINT_QUERY (boolean) DEBUG_PRETTY_PRINT (boolean) For any executed query, prints either the query, the parse tree, the execution plan, or the query rewriter output to the server log. selects are nicer but longer output format. HOSTLOOKUP (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) Prints a line informing about each successful connection to the server log. This is off by default, although it is probably very useful. This option can only be set at server start. 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 timestamp. 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. SHOWPORTNUMBER (boolean) Shows the 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. SYSLOG (integer) Postgres 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 Postgres must be configured with the option. TRACE_NOTIFY (boolean) Generates a great amount of debugging output for the LISTEN and NOTIFY commands. General operation 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 or not. The check for deadlock is relatively slow, so we don't want to run it every time we wait for a lock. We (optimistically?) assume that deadlocks are not common in production applications, and just wait on the lock for awhile before starting to ask questions about whether it can ever get unlocked. 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. FSYNC (boolean) If this is option is on, the Postgres backend will use the fsync() system call in several places to make sure that updates are physically written to disk and will not hang around in the write caches. This increases the chance that a database installation will still be usable after a operating system or hardware crashes by a large amount. (Crashes of the database server itself do not affect this consideration.) However, this operation severely slows down Postgres, because at all those points it has to block and wait for the operating system to flush the buffers. Without fsync, the operating system is allowed to do its best in buffering, sorting, and delaying writes, so this can be a very big perfomance increase. However, if the system crashes, parts of the data of a transaction that has already been committed -- according to the information on disk -- will still hang around in memory. Inconsistent data (i.e., data corruption) is therefore likely to occur. This option is the subject of an eternal debate in the Postgres user and developer communities. Some always leave it off, some turn it off only for bulk loads, where there is a clear restart point if something goes wrong, some leave it on just to be on the safe side. Because it is the safe side, on is also the default. If you trust your operating system, your utility company, and your hardware, you might want to disable it. KRB_SERVER_KEYFILE Sets the location of the Kerberos server key file. See for details. MAX_CONNECTIONS (integer) Determines how many concurrent connections the database server will allow. The default is 32. There is also a compiled-in hard upper limit on this value, which is typically 1024 (both numbers can be altered when compiling the server). This parameter can only be set at server start. MAX_EXPR_DEPTH (integer) Sets the maximum expression nesting depth that the parser will accept. The default value is high enough for any normal query, but you can raise it if you need to. (But if you raise it too high, you run the risk of backend crashes due to stack overflow.) PORT (integer) 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 the database server will use. 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, postmaser will automatically run in background and any controlling ttys are disassociated, thus no message is put to stdout or stderr(same effect as postmaster's -S option). Unless some logging systems such as syslog is enabled, using this option is discouraged since it makes difficult to find error messages. SORT_MEM (integer) Specifies the amount of memory to be used by internal sorts and hashes before resorting 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. SQL_INHERITANCE (bool) This controls the inheritance semantics, in particular whether subtables are included into the consideration of various commands by default. This was not the case in versions prior to 7.1. If you need the old behaviour 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 (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. 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 would be 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 from the one described in . This option can only be set at server start. 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 -B x shared_buffers = x -d x debug_level = x -F fsync = off -i tcpip_socket = on -l ssl = on -N x max_connections = x -p x port = x -fi, -fh, -fm, -fn, -fs, -ft enable_indexscan=off, enable_hashjoin=off, enable_mergejoin=off, enable_nestloop=off, enable_seqscan=off, enable_tidscan=off * -S x sort_mem = x * -s show_query_stats = on * -tpa, -tpl, -te 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 Postgres installation can quickly hit 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 then keep reading. Shared Memory and Semaphores Shared memory and semaphores are collectively referred to as System V IPC (together with message queues, which are not relevant for Postgres). 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 port, Postgres 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 -- Postgres won't work without them. When Postgres exceeds one of the various hard limits of the IPC resources then the postmaster will refuse to start up and should leave a marginally instructive error message about which problem was encountered and what needs to be done about it. 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 aware that you will have to reboot your machine at least, possibly even recompile the kernel, to change these settings. System V 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>512 kB + 8192 * buffers + extra ... infinity</entry> </row> <row> <entry><varname>SHMMIN</></> <entry>Minimum size of shared memory segment (bytes)</> <entry>1 (at most 144)</> </row> <row> <entry><varname>SHMSEG</></> <entry>Maximum number of shared memory segments per process</> <entry>must be at least 3, but the default is much higher</> </row> <row> <entry><varname>SHMMNI</></> <entry>Maximum number of shared memory segments system-wide</> <entry>like <varname>SHMSEG</> + room for other applications</> </row> <row> <entry><varname>SEMMNI</></> <entry>Maximum number of semaphore identifiers (i.e., sets)</> <entry>>= ceil(max_connections / 16)</> </row> <row> <entry><varname>SEMMNS</></> <entry>Maximum number of semaphores system-wide</> <entry>max_connections rounded up to multiple of 16, + room for other applications</> </row> <row> <entry><varname>SEMMSL</></> <entry>Maximum number of semaphores per set</> <entry>>= 16</> </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> The most important shared memory parameter is <varname>SHMMAX</>, the maximum size, in bytes, that a shared memory segment can have. If you get an error message from <function>shmget</> along the lines of <errorname>Invalid argument</> then it is possible that this limit has been exceeded. The size of the required shared memory segments 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 dominant item. (You can therefore, as a temporary solution, lower these settings to get rid of the failures.) As a rough approximation you can estimate the required segment size as the number of buffers times the block size (8192 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. (<productname>Postgres</> will actually use three shared memory segments, but the size of the other two is negligible for this consideration.) </para> <para> Less likely to cause problems is the minimum size for shared memory segments (<varname>SHMMIN</>), which must be at least 144 for <productname>Postgres</> (it's usually just 1), and the maximum number of segments system-wide (<varname>SHMMNI</>, as mentioned, 3 are needed) or per-process (<varname>SHMSEG</>, ditto). 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>Postgres</> uses one semaphore per allowed connection (<option>-N</> option), in sets of 16. 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. 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 turn out to 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 therefore over time lead to less 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 16 for <productname>Postgres</>. </para> <para> Various other settings related to <quote>semaphore undo</>, such as <varname>SEMMNU</> and <varname>SEMUME</>, are not of concern for <productname>Postgres</>. </para> <para> <variablelist> <varlistentry> <term>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 buffers supported by the postmaster, increase <varname>SHMMAXPGS</> by 1024 for every additional 4 MB of shared memory: <programlisting> /sys/sys/shm.h:69:#define SHMMAXPGS 1024 /* max hardware pages... */ </programlisting> The default setting of 1024 provides a maximum of 4 MB of shared memory. </para> </formalpara> <para> For those running 4.1 or later, just recompile the kernel and reboot. For those running earlier releases, use <application>bpatch</> to find the <varname>sysptsize</> value for the current kernel. This is computed dynamically at bootup. <screen> $ <userinput>bpatch -r sysptsize</> <computeroutput>0x9 = 9</> </screen> Next, change <varname>SYSPTSIZE</> to a hard-coded value. Use the bpatch value, plus add 1 for every additional 4 MB of shared memory you desire. <programlisting> /sys/i386/i386/i386_param.c:28:#define SYSPTSIZE 0 /* dynamically... */ </programlisting> <varname>sysptsize</> can not be changed by sysctl on the fly. </para> <formalpara> <title>Semaphores</> <para> You may need to increase the number of semaphores. By default, <productname>Postgres</> allocates 32 semaphores, one for each backend connection. This is just over half the default system total of 60. </para> </formalpara> <para> The defaults are in <filename>/sys/sys/sem.h</>: <programlisting> /* Configuration parameters */ #ifndef SEMMNI #define SEMMNI 10 /* # of semaphore identifiers */ #endif #ifndef SEMMNS #define SEMMNS 60 /* # of semaphores in system */ #endif #ifndef SEMUME #define SEMUME 10 /* max # of undo entries per process */ #endif #ifndef SEMMNU #define SEMMNU 30 /* # of undo structures in system */ #endif </programlisting> Set the values you want in your kernel config file, e.g.: <programlisting> options "SEMMNI=40" options "SEMMNS=240" options "SEMUME=40" options "SEMMNU=120" </programlisting> </para> </listitem> </varlistentry> <varlistentry> <term>FreeBSD</> <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> </para> </listitem> </varlistentry> <varlistentry> <term>HPUX</> <listitem> <para> The default settings tend to suffice for normal installations. On <productname>HPUX</> 10, the factory default for <varname>SEMMNS</> is 128, which might be too low for larger database sites. </para> <para> 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>Linux</> <listitem> <para> System V IPC is enabled by default and sufficiently sized for most uses. The relevant parameters are in <filename>/usr/src/linux/include/asm-<replaceable>xxx</>/shmparam.h</> and <filename>/usr/src/linux/include/linux/sem.h</>. Be sure to do <command>make dep</> before rebuilding the kernel. </para> </listitem> </varlistentry> <varlistentry> <term>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 the 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>Solaris</> <listitem> <para> At least in version 2.6, the maximum size of a shared memory segment is set too low for <productname>Postgres</>. 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 to make the changes effective. </para> <para> See also <ulink url="http://www.sunworld.com/swol-09-1997/swol-09-insidesolaris.html">http://www.sunworld.com/swol-09-1997/swol-09-insidesolaris.html</> for information on shared memory under <productname>Solaris</>. </para> </listitem> </varlistentry> <varlistentry> <term>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> <note> <para> If your platform is not listed here, please consider contributing some information. </para> </note> </para> </sect2> <!-- Other fun things to write about one day: * number of processes per user and system-wide (soft/hard limit) * open files/inodes per user and system-wide (soft/hard limit) (Think about this both ways: Increasing it to allow Postgres to open more files, and decreasing it to prevent Postgres from taking up all file descriptors.) * stack and data segment size, plain-old memory limit --> </sect1> <sect1 id="postmaster-shutdown"> <title>Shutting down the server Depending on your needs, there are several ways to shut down the database server when your work is done. The differentiation is done by what signal you send to the server process. SIGTERM After receiving SIGTERM, the postmaster disallows new connections but lets active backend end their work and shuts down only after all of them terminated (by client request). This is the Smart Shutdown. SIGINT The postmaster disallows new connections, sends all active backends SIGTERM (which will cause them to abort immediately), waits for children to exit and shuts down the data base. This is the Fast Shutdown. SIGQUIT This is the Immediate Shutdown which will cause the postmaster to send a SIGUSR1 to all backends and exit immediately (without properly shutting down the database system). When WAL is implemented, this will lead to recovery on start-up. Right now it's not recommendable to use this option. If at all possible, do not use SIGKILL to shut down the postmaster. This can cause data corruption and will prevent the cleaning up of shared memory resources, which you will have to do yourself in that case. 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 `cat /usr/local/pgsql/data/postmaster.pid` The program pg_ctl is a shell script wrapper that provides a convenient interface to these functions. Secure TCP/IP Connections with SSL PostgreSQL has native support for connections over SSL to encrypt client/server communications for increased security. This requires OpenSSL to 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 postmaster will listen for both standard and SSL connections on the same TCP/IP port, and will negotiate with any connecting client whether or not to use SSL. See about how to force on the server side the 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 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 servers identity. To create a quick self-signed certificate, use the CA.pl script included in OpenSSL: CA.pl -newcert Fill out the information the script asks for. Make sure to enter the local host name as Common Name. The script will generate a key that is passphrase protected. To remove the passphrase (required if you want automatic start-up of the postmaster), run the command openssl x509 -inform PEM -outform PEM -in newreq.pem -out newkey_no_passphrase.pem Enter the old passphrase to unlock the existing key. Copy the file newreq.pem to PGDATA/server.crt and newkey_no_passphrase.pem to PGDATA/server.key. Remove the PRIVATE KEY part from the server.crt using any text editor. Secure TCP/IP Connections with SSH tunnels 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 Postgres 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 Postgres 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 backend 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.