Reliability and the Write-Ahead Log
 
  This chapter explains how the Write-Ahead Log is used to obtain
  efficient, reliable operation.
 
 
  Reliability
  
   Reliability is an important property of any serious database
   system, and PostgreSQL> does everything possible to
   guarantee reliable operation. One aspect of reliable operation is
   that all data recorded by a committed transaction should be stored
   in a nonvolatile area that is safe from power loss, operating
   system failure, and hardware failure (except failure of the
   nonvolatile area itself, of course).  Successfully writing the data
   to the computer's permanent storage (disk drive or equivalent)
   ordinarily meets this requirement.  In fact, even if a computer is
   fatally damaged, if the disk drives survive they can be moved to
   another computer with similar hardware and all committed
   transactions will remain intact.
  
  
   While forcing data periodically to the disk platters might seem like
   a simple operation, it is not. Because disk drives are dramatically
   slower than main memory and CPUs, several layers of caching exist
   between the computer's main memory and the disk platters.
   First, there is the operating system's buffer cache, which caches
   frequently requested disk blocks and combines disk writes. Fortunately,
   all operating systems give applications a way to force writes from
   the buffer cache to disk, and PostgreSQL> uses those
   features.  (See the  parameter
   to adjust how this is done.)
  
  
   Next, there might be a cache in the disk drive controller; this is
   particularly common on RAID> controller cards. Some of
   these caches are write-through>, meaning writes are passed
   along to the drive as soon as they arrive. Others are
   write-back>, meaning data is passed on to the drive at
   some later time. Such caches can be a reliability hazard because the
   memory in the disk controller cache is volatile, and will lose its
   contents in a power failure.  Better controller cards have
   battery-backed> caches, meaning the card has a battery that
   maintains power to the cache in case of system power loss.  After power
   is restored the data will be written to the disk drives.
  
  
   And finally, most disk drives have caches. Some are write-through
   while some are write-back, and the
   same concerns about data loss exist for write-back drive caches as
   exist for disk controller caches.  Consumer-grade IDE and SATA drives are
   particularly likely to have write-back caches that will not survive a
   power failure.  To check write caching on Linux> use
   hdparm -I>;  it is enabled if there is a *> next
   to Write cache>.  hdparm -W> to turn off
   write caching.  On FreeBSD> use
   atacontrol>.  (For SCSI disks use sdparm>
   to turn off WCE>.)  On Solaris> the disk
   write cache is controlled by format
   -e>. (The Solaris ZFS> file system is safe with
   disk write-cache enabled because it issues its own disk cache flush
   commands.)  On Windows> if wal_sync_method>
   is open_datasync> (the default), write caching is disabled
   by unchecking My Computer\Open\{select disk
   drive}\Properties\Hardware\Properties\Policies\Enable write caching on
   the disk>.  Also on Windows, fsync> and
   fsync_writethrough> never do write caching.
  
  
   When the operating system sends a write request to the disk hardware,
   there is little it can do to make sure the data has arrived at a truly
   non-volatile storage area. Rather, it is the
   administrator's responsibility to be sure that all storage components
   ensure data integrity.  Avoid disk controllers that have non-battery-backed
   write caches.  At the drive level, disable write-back caching if the
   drive cannot guarantee the data will be written before shutdown.
  
  
   Another risk of data loss is posed by the disk platter write
   operations themselves. Disk platters are divided into sectors,
   commonly 512 bytes each.  Every physical read or write operation
   processes a whole sector.
   When a write request arrives at the drive, it might be for 512 bytes,
   1024 bytes, or 8192 bytes, and the process of writing could fail due
   to power loss at any time, meaning some of the 512-byte sectors were
   written, and others were not.  To guard against such failures,
   PostgreSQL> periodically writes full page images to
   permanent storage before> modifying the actual page on
   disk. By doing this, during crash recovery PostgreSQL> can
   restore partially-written pages.  If you have a battery-backed disk
   controller or file-system software that prevents partial page writes
   (e.g., ReiserFS 4),  you can turn off this page imaging by using the
    parameter.
  
 
  
   Write-Ahead Logging (WAL)
   
    WAL
   
   
    transaction log
    WAL
   
   
    Write-Ahead Logging (WAL)
    is a standard method for ensuring data integrity.  A detailed
    description can be found in most (if not all) books about
    transaction processing. Briefly, WAL's central
    concept is that changes to data files (where tables and indexes
    reside) must be written only after those changes have been logged,
    that is, after log records describing the changes have been flushed
    to permanent storage. If we follow this procedure, we do not need
    to flush data pages to disk on every transaction commit, because we
    know that in the event of a crash we will be able to recover the
    database using the log: any changes that have not been applied to
    the data pages can be redone from the log records.  (This is
    roll-forward recovery, also known as REDO.)
   
   
    Using WAL results in a
    significantly reduced number of disk writes, because only the log
    file needs to be flushed to disk to guarantee that a transaction is
    committed, rather than every data file changed by the transaction.
    The log file is written sequentially,
    and so the cost of syncing the log is much less than the cost of
    flushing the data pages.  This is especially true for servers
    handling many small transactions touching different parts of the data
    store.  Furthermore, when the server is processing many small concurrent
    transactions, one fsync of the log file may
    suffice to commit many transactions.
   
   
    WAL also makes it possible to support on-line
    backup and point-in-time recovery, as described in .  By archiving the WAL data we can support
    reverting to any time instant covered by the available WAL data:
    we simply install a prior physical backup of the database, and
    replay the WAL log just as far as the desired time.  What's more,
    the physical backup doesn't have to be an instantaneous snapshot
    of the database state — if it is made over some period of time,
    then replaying the WAL log for that period will fix any internal
    inconsistencies.
   
  
 
  Asynchronous Commit
   
    synchronous commit
   
   
    asynchronous commit
   
  
   Asynchronous commit> is an option that allows transactions
   to complete more quickly, at the cost that the most recent transactions may
   be lost if the database should crash.  In many applications this is an
   acceptable trade-off.
  
  
   As described in the previous section, transaction commit is normally
   synchronous>: the server waits for the transaction's
   WAL records to be flushed to permanent storage
   before returning a success indication to the client.  The client is
   therefore guaranteed that a transaction reported to be committed will
   be preserved, even in the event of a server crash immediately after.
   However, for short transactions this delay is a major component of the
   total transaction time.  Selecting asynchronous commit mode means that
   the server returns success as soon as the transaction is logically
   completed, before the WAL records it generated have
   actually made their way to disk.  This can provide a significant boost
   in throughput for small transactions.
  
  
   Asynchronous commit introduces the risk of data loss. There is a short
   time window between the report of transaction completion to the client
   and the time that the transaction is truly committed (that is, it is
   guaranteed not to be lost if the server crashes).  Thus asynchronous
   commit should not be used if the client will take external actions
   relying on the assumption that the transaction will be remembered.
   As an example, a bank would certainly not use asynchronous commit for
   a transaction recording an ATM's dispensing of cash.  But in many
   scenarios, such as event logging, there is no need for a strong
   guarantee of this kind.
  
  
   The risk that is taken by using asynchronous commit is of data loss,
   not data corruption.  If the database should crash, it will recover
   by replaying WAL up to the last record that was
   flushed.  The database will therefore be restored to a self-consistent
   state, but any transactions that were not yet flushed to disk will
   not be reflected in that state.  The net effect is therefore loss of
   the last few transactions.  Because the transactions are replayed in
   commit order, no inconsistency can be introduced — for example,
   if transaction B made changes relying on the effects of a previous
   transaction A, it is not possible for A's effects to be lost while B's
   effects are preserved.
  
  
   The user can select the commit mode of each transaction, so that
   it is possible to have both synchronous and asynchronous commit
   transactions running concurrently.  This allows flexible trade-offs
   between performance and certainty of transaction durability.
   The commit mode is controlled by the user-settable parameter
   , which can be changed in any of
   the ways that a configuration parameter can be set.  The mode used for
   any one transaction depends on the value of
   synchronous_commit when transaction commit begins.
  
  
   Certain utility commands, for instance DROP TABLE>, are
   forced to commit synchronously regardless of the setting of
   synchronous_commit.  This is to ensure consistency
   between the server's file system and the logical state of the database.
   The commands supporting two-phase commit, such as PREPARE
   TRANSACTION>, are also always synchronous.
  
  
   If the database crashes during the risk window between an
   asynchronous commit and the writing of the transaction's
   WAL records,
   then changes made during that transaction will> be lost.
   The duration of the
   risk window is limited because a background process (the WAL
   writer>) flushes unwritten WAL records to disk
   every  milliseconds.
   The actual maximum duration of the risk window is three times
   wal_writer_delay because the WAL writer is
   designed to favor writing whole pages at a time during busy periods.
  
  
   
    An immediate-mode shutdown is equivalent to a server crash, and will
    therefore cause loss of any unflushed asynchronous commits.
   
  
  
   Asynchronous commit provides behavior different from setting
    = off.
   fsync is a server-wide
   setting that will alter the behavior of all transactions.  It disables
   all logic within PostgreSQL> that attempts to synchronize
   writes to different portions of the database, and therefore a system
   crash (that is, a hardware or operating system crash, not a failure of
   PostgreSQL> itself) could result in arbitrarily bad
   corruption of the database state.  In many scenarios, asynchronous
   commit provides most of the performance improvement that could be
   obtained by turning off fsync, but without the risk
   of data corruption.
  
  
    also sounds very similar to
   asynchronous commit, but it is actually a synchronous commit method
   (in fact, commit_delay is ignored during an
   asynchronous commit).  commit_delay causes a delay
   just before a synchronous commit attempts to flush
   WAL to disk, in the hope that a single flush
   executed by one such transaction can also serve other transactions
   committing at about the same time.  Setting commit_delay
   can only help when there are many concurrently committing transactions,
   and it is difficult to tune it to a value that actually helps rather
   than hurting throughput.
  
 
 
  WAL Configuration
  
   There are several WAL>-related configuration parameters that
   affect database performance. This section explains their use.
   Consult  for general information about
   setting server configuration parameters.
  
  
   Checkpointscheckpoint>>
   are points in the sequence of transactions at which it is guaranteed
   that the data files have been updated with all information written before
   the checkpoint.  At checkpoint time, all dirty data pages are flushed to
   disk and a special checkpoint record is written to the log file.
   In the event of a crash, the crash recovery procedure looks at the latest
   checkpoint record to determine the point in the log (known as the redo
   record) from which it should start the REDO operation.  Any changes made to
   data files before that point are known to be already on disk.  Hence, after
   a checkpoint has been made, any log segments preceding the one containing
   the redo record are no longer needed and can be recycled or removed. (When
   WAL archiving is being done, the log segments must be
   archived before being recycled or removed.)
  
  
   The server's background writer process will automatically perform
   a checkpoint every so often.  A checkpoint is created every  log segments, or every  seconds, whichever comes first.
   The default settings are 3 segments and 300 seconds respectively.
   It is also possible to force a checkpoint by using the SQL command
   CHECKPOINT.
  
  
   Reducing checkpoint_segments and/or
   checkpoint_timeout causes checkpoints to be done
   more often. This allows faster after-crash recovery (since less work
   will need to be redone). However, one must balance this against the
   increased cost of flushing dirty data pages more often. If
    is set (as is the default), there is
   another factor to consider. To ensure data page consistency,
   the first modification of a data page after each checkpoint results in
   logging the entire page content. In that case,
   a smaller checkpoint interval increases the volume of output to the WAL log,
   partially negating the goal of using a smaller interval,
   and in any case causing more disk I/O.
  
  
   Checkpoints are fairly expensive, first because they require writing
   out all currently dirty buffers, and second because they result in
   extra subsequent WAL traffic as discussed above.  It is therefore
   wise to set the checkpointing parameters high enough that checkpoints
   don't happen too often.  As a simple sanity check on your checkpointing
   parameters, you can set the 
   parameter.  If checkpoints happen closer together than
   checkpoint_warning> seconds,
   a message will be output to the server log recommending increasing
   checkpoint_segments.  Occasional appearance of such
   a message is not cause for alarm, but if it appears often then the
   checkpoint control parameters should be increased. Bulk operations such
   as large COPY> transfers might cause a number of such warnings
   to appear if you have not set checkpoint_segments> high
   enough.
  
  
   To avoid flooding the I/O system with a burst of page writes,
   writing dirty buffers during a checkpoint is spread over a period of time.
   That period is controlled by
   , which is
   given as a fraction of the checkpoint interval.
   The I/O rate is adjusted so that the checkpoint finishes when the
   given fraction of checkpoint_segments WAL segments
   have been consumed since checkpoint start, or the given fraction of
   checkpoint_timeout seconds have elapsed,
   whichever is sooner.  With the default value of 0.5,
   PostgreSQL> can be expected to complete each checkpoint
   in about half the time before the next checkpoint starts.  On a system
   that's very close to maximum I/O throughput during normal operation,
   you might want to increase checkpoint_completion_target
   to reduce the I/O load from checkpoints.  The disadvantage of this is that
   prolonging checkpoints affects recovery time, because more WAL segments
   will need to be kept around for possible use in recovery.  Although
   checkpoint_completion_target can be set as high as 1.0,
   it is best to keep it less than that (perhaps 0.9 at most) since
   checkpoints include some other activities besides writing dirty buffers.
   A setting of 1.0 is quite likely to result in checkpoints not being
   completed on time, which would result in performance loss due to
   unexpected variation in the number of WAL segments needed.
  
  
   There will always be at least one WAL segment file, and will normally
   not be more than (2 + checkpoint_completion_target) * checkpoint_segments + 1
   files.  Each segment file is normally 16 MB (though this size can be
   altered when building the server).  You can use this to estimate space
   requirements for WAL.
   Ordinarily, when old log segment files are no longer needed, they
   are recycled (renamed to become the next segments in the numbered
   sequence). If, due to a short-term peak of log output rate, there
   are more than 3 * checkpoint_segments + 1
   segment files, the unneeded segment files will be deleted instead
   of recycled until the system gets back under this limit.
  
  
   There are two commonly used internal WAL functions:
   LogInsert and LogFlush.
   LogInsert is used to place a new record into
   the WAL buffers in shared memory. If there is no
   space for the new record, LogInsert will have
   to write (move to kernel cache) a few filled WAL
   buffers. This is undesirable because LogInsert
   is used on every database low level modification (for example, row
   insertion) at a time when an exclusive lock is held on affected
   data pages, so the operation needs to be as fast as possible.  What
   is worse, writing WAL buffers might also force the
   creation of a new log segment, which takes even more
   time. Normally, WAL buffers should be written
   and flushed by a LogFlush request, which is
   made, for the most part, at transaction commit time to ensure that
   transaction records are flushed to permanent storage. On systems
   with high log output, LogFlush requests might
   not occur often enough to prevent LogInsert
   from having to do writes.  On such systems
   one should increase the number of WAL buffers by
   modifying the configuration parameter .  The default number of WAL
   buffers is 8.  Increasing this value will
   correspondingly increase shared memory usage.  When
    is set and the system is very busy,
   setting this value higher will help smooth response times during the
   period immediately following each checkpoint.
  
  
   The  parameter defines for how many
   microseconds the server process will sleep after writing a commit
   record to the log with LogInsert but before
   performing a LogFlush. This delay allows other
   server processes to add their commit records to the log so as to have all
   of them flushed with a single log sync. No sleep will occur if
   
   is not enabled, nor if fewer than 
   other sessions are currently in active transactions; this avoids
   sleeping when it's unlikely that any other session will commit soon.
   Note that on most platforms, the resolution of a sleep request is
   ten milliseconds, so that any nonzero commit_delay
   setting between 1 and 10000 microseconds would have the same effect.
   Good values for these parameters are not yet clear; experimentation
   is encouraged.
  
  
   The  parameter determines how
   PostgreSQL will ask the kernel to force
    WAL updates out to disk.
   All the options should be the same as far as reliability goes,
   but it's quite platform-specific which one will be the fastest.
   Note that this parameter is irrelevant if fsync
   has been turned off.
  
  
   Enabling the  configuration parameter
   (provided that PostgreSQL has been
   compiled with support for it) will result in each
   LogInsert and LogFlush
   WAL call being logged to the server log. This
   option might be replaced by a more general mechanism in the future.
  
 
 
  WAL Internals
  
   WAL is automatically enabled; no action is
   required from the administrator except ensuring that the
   disk-space requirements for the WAL logs are met,
   and that any necessary tuning is done (see ).
  
  
   WAL logs are stored in the directory
   pg_xlog under the data directory, as a set of
   segment files, normally each 16 MB in size.  Each segment is divided into
   pages, normally 8 kB each.  The log record headers are described in
   access/xlog.h; the record content is dependent
   on the type of event that is being logged.  Segment files are given
   ever-increasing numbers as names, starting at
   000000010000000000000000.  The numbers do not wrap, at
   present, but it should take a very very long time to exhaust the
   available stock of numbers.
  
  
   It is of advantage if the log is located on another disk than the
   main database files.  This can be achieved by moving the directory
   pg_xlog to another location (while the server
   is shut down, of course) and creating a symbolic link from the
   original location in the main data directory to the new location.
  
  
   The aim of WAL, to ensure that the log is
   written before database records are altered, can be subverted by
   disk drivesdisk drive>> that falsely report a
   successful write to the kernel,
   when in fact they have only cached the data and not yet stored it
   on the disk.  A power failure in such a situation might still lead to
   irrecoverable data corruption.  Administrators should try to ensure
   that disks holding PostgreSQL's
   WAL log files do not make such false reports.
  
  
   After a checkpoint has been made and the log flushed, the
   checkpoint's position is saved in the file
   pg_control. Therefore, when recovery is to be
   done, the server first reads pg_control and
   then the checkpoint record; then it performs the REDO operation by
   scanning forward from the log position indicated in the checkpoint
   record.  Because the entire content of data pages is saved in the
   log on the first page modification after a checkpoint, all pages
   changed since the checkpoint will be restored to a consistent
   state.
  
  
   To deal with the case where pg_control is
   corrupted, we should support the possibility of scanning existing log
   segments in reverse order — newest to oldest — in order to find the
   latest checkpoint.  This has not been implemented yet.
   pg_control is small enough (less than one disk page)
   that it is not subject to partial-write problems, and as of this writing
   there have been no reports of database failures due solely to inability
   to read pg_control itself.  So while it is
   theoretically a weak spot, pg_control does not
   seem to be a problem in practice.