17.5. Write Ahead Log

See also Section 26.2 for details on WAL tuning.

17.5.1. Settings

fsync (boolean)

If this option is on, the PostgreSQL server will use the fsync() system call in several places to make sure that updates are physically written to disk. This insures that a database cluster will recover to a consistent state after an operating system or hardware crash.

However, using fsync() results in a performance penalty: when a transaction is committed, PostgreSQL must wait for the operating system to flush the write-ahead log to disk. When fsync is disabled, the operating system is allowed to do its best in buffering, ordering, and delaying writes. This can result in significantly improved performance. However, if the system crashes, the results of the last few committed transactions may be lost in part or whole. In the worst case, unrecoverable data corruption may occur. (Crashes of the database server itself are not a risk factor here. Only an operating-system-level crash creates a risk of corruption.)

Due to the risks involved, there is no universally correct setting for fsync. Some administrators always disable fsync, while others only turn it off for bulk loads, where there is a clear restart point if something goes wrong, whereas some administrators always leave fsync enabled. The default is to enable fsync, for maximum reliability. If you trust your operating system, your hardware, and your utility company (or your battery backup), you can consider disabling fsync.

This option can only be set at server start or in the postgresql.conf file. If this option is off, consider also turning off guc-full-page-writes.

wal_sync_method (string)

Method used for forcing WAL updates out to disk. Possible values are:

  • open_datasync (write WAL files with open() option O_DSYNC)

  • fdatasync (call fdatasync() at each commit),

  • fsync (call fsync() at each commit)

  • fsync_writethrough (force write-through of any disk write cache)

  • open_sync (write WAL files with open() option O_SYNC)

Not all of these choices are available on all platforms. The top-most supported option is used as the default. If fsync is off then this setting is irrelevant. This option can only be set at server start or in the postgresql.conf file.

full_page_writes (boolean)

A page write in process during an operating system crash might be only partially written to disk, leading to an on-disk page that contains a mix of old and new data. During recovery, the row changes stored in WAL are not enough to completely restore the page.

When this option is on, the PostgreSQL server writes full pages to WAL when they are first modified after a checkpoint so full recovery is possible. Turning this option off might lead to a corrupt system after an operating system crash or power failure because uncorrected partial pages might contain inconsistent or corrupt data. The risks are less but similar to fsync.

This option can only be set at server start or in the postgresql.conf file. The default is on.

wal_buffers (integer)

Number of disk-page buffers allocated in shared memory for WAL data. The default is 8. The setting need only be large enough to hold the amount of WAL data generated by one typical transaction, since the data is flushed to disk at every transaction commit. This option can only be set at server start.

Increasing this parameter may cause PostgreSQL to request more System V shared memory than your operating system's default configuration allows. See Section 16.4.1 for information on how to adjust those parameters, if necessary.

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 can allow multiple transactions to be committed with only one fsync() system call, if system load is high enough that additional transactions become ready to commit within the given interval. But the delay is just wasted if no other transactions become ready to commit. Therefore, the delay is only performed if at least commit_siblings other transactions are active at the instant that a server process has written its commit record. The default is zero (no delay).

commit_siblings (integer)

Minimum number of concurrent open transactions to require before performing the commit_delay delay. A larger value makes it more probable that at least one other transaction will become ready to commit during the delay interval. The default is five.

17.5.2. Checkpoints

checkpoint_segments (integer)

Maximum distance between automatic WAL checkpoints, in log file segments (each segment is normally 16 megabytes). The default is three. This option can only be set at server start or in the postgresql.conf file.

checkpoint_timeout (integer)

Maximum time between automatic WAL checkpoints, in seconds. The default is 300 seconds. This option can only be set at server start or in the postgresql.conf file.

checkpoint_warning (integer)

Write a message to the server log if checkpoints caused by the filling of checkpoint segment files happen closer together than this many seconds. The default is 30 seconds. Zero turns off the warning.

17.5.3. Archiving

archive_command (string)

The shell command to execute to archive a completed segment of the WAL file series. If this is an empty string (the default), WAL archiving is disabled. Any %p in the string is replaced by the absolute path of the file to archive, and any %f is replaced by the file name only. Use %% to embed an actual % character in the command. For more information see Section 23.3.1. This option can only be set at server start or in the postgresql.conf file.

It is important for the command to return a zero exit status if and only if it succeeds. Examples:

archive_command = 'cp "%p" /mnt/server/archivedir/"%f"'
archive_command = 'copy "%p" /mnt/server/archivedir/"%f"'  # Windows