postgresql/doc/src/sgml/maintenance.sgml

750 lines
33 KiB
Plaintext
Raw Normal View History

<!-- $PostgreSQL: pgsql/doc/src/sgml/maintenance.sgml,v 1.71 2007/04/16 18:29:50 alvherre Exp $ -->
<chapter id="maintenance">
<title>Routine Database Maintenance Tasks</title>
2003-08-31 19:32:24 +02:00
<indexterm zone="maintenance">
<primary>maintenance</primary>
</indexterm>
<indexterm zone="maintenance">
<primary>routine maintenance</primary>
</indexterm>
<para>
<productname>PostgreSQL</>, like any database software, requires that certain tasks
be performed regularly to achieve optimum performance. The tasks
discussed here are <emphasis>required</emphasis>, but they
are repetitive in nature and can easily be automated using standard
Unix tools such as <application>cron</application> scripts or
Windows' <application>Task Scheduler</>. But it is the database
administrator's responsibility to set up appropriate scripts, and to
check that they execute successfully.
</para>
<para>
One obvious maintenance task is creation of backup copies of the data on a
regular schedule. Without a recent backup, you have no chance of recovery
after a catastrophe (disk failure, fire, mistakenly dropping a critical
table, etc.). The backup and recovery mechanisms available in
<productname>PostgreSQL</productname> are discussed at length in
<xref linkend="backup">.
</para>
<para>
The other main category of maintenance task is periodic <quote>vacuuming</>
of the database. This activity is discussed in
<xref linkend="routine-vacuuming">. Closely related to this is updating
the statistics that will be used by the query planner, as discussed in
<xref linkend="vacuum-for-statistics">.
</para>
<para>
Another task that might need periodic attention is log file management.
This is discussed in <xref linkend="logfile-maintenance">.
</para>
<para>
<productname>PostgreSQL</productname> is low-maintenance compared
to some other database management systems. Nonetheless,
appropriate attention to these tasks will go far towards ensuring a
pleasant and productive experience with the system.
</para>
<sect1 id="routine-vacuuming">
<title>Routine Vacuuming</title>
2001-11-12 20:19:39 +01:00
<indexterm zone="routine-vacuuming">
<primary>vacuum</primary>
</indexterm>
<para>
<productname>PostgreSQL</productname>'s <command>VACUUM</> command
<emphasis>must</emphasis> be run on a regular basis for several reasons:
<orderedlist>
<listitem>
<simpara>To recover or reuse disk space occupied by updated or deleted
rows.</simpara>
</listitem>
<listitem>
<simpara>To update data statistics used by the
<productname>PostgreSQL</productname> query planner.</simpara>
</listitem>
<listitem>
<simpara>To protect against loss of very old data due to
<firstterm>transaction ID wraparound</>.</simpara>
</listitem>
</orderedlist>
The frequency and scope of the <command>VACUUM</> operations
performed for each of these reasons will vary depending on the
needs of each site. Therefore, database administrators must
understand these issues and develop an appropriate maintenance
strategy. This section concentrates on explaining the high-level
issues; for details about command syntax and so on, see the <xref
linkend="sql-vacuum" endterm="sql-vacuum-title"> reference page.
</para>
<para>
The standard form of <command>VACUUM</> can run in parallel with production
2006-10-23 20:10:32 +02:00
database operations. Commands such as <command>SELECT</command>,
<command>INSERT</command>, <command>UPDATE</command>, and <command>DELETE</command>
will continue to function as normal, though you will not be able to modify the
2006-10-23 20:10:32 +02:00
definition of a table with commands such as <command>ALTER TABLE ADD COLUMN</command>
while it is being vacuumed.
Also, <command>VACUUM</command> requires a substantial amount of I/O
traffic, which can cause poor performance for other active sessions.
There are configuration parameters that can be adjusted to reduce the
performance impact of background vacuuming &mdash; see
2004-12-27 23:30:10 +01:00
<xref linkend="runtime-config-resource-vacuum-cost">.
</para>
2005-09-13 03:51:18 +02:00
<para>
An automated mechanism for performing the necessary <command>VACUUM</>
operations has been added in <productname>PostgreSQL</productname> 8.1.
See <xref linkend="autovacuum">.
</para>
<sect2 id="vacuum-for-space-recovery">
<title>Recovering disk space</title>
2001-11-12 20:19:39 +01:00
<indexterm zone="vacuum-for-space-recovery">
<primary>disk space</primary>
</indexterm>
<para>
In normal <productname>PostgreSQL</productname> operation, an
<command>UPDATE</> or <command>DELETE</> of a row does not
immediately remove the old version of the row.
This approach is necessary to gain the benefits of multiversion
concurrency control (see <xref linkend="mvcc">): the row version
must not be deleted while it is still potentially visible to other
transactions. But eventually, an outdated or deleted row version is no
longer of interest to any transaction. The space it occupies must be
reclaimed for reuse by new rows, to avoid infinite growth of disk
space requirements. This is done by running <command>VACUUM</>.
</para>
<para>
Clearly, a table that receives frequent updates or deletes will need
to be vacuumed more often than tables that are seldom updated. It
might be useful to set up periodic <application>cron</> tasks that
<command>VACUUM</command> only selected tables, skipping tables that are known not to
change often. This is only likely to be helpful if you have both
large heavily-updated tables and large seldom-updated tables &mdash; the
extra cost of vacuuming a small table isn't enough to be worth
worrying about.
</para>
<para>
There are two variants of the <command>VACUUM</command>
command. The first form, known as <quote>lazy vacuum</quote> or
just <command>VACUUM</command>, marks dead data in tables and
indexes for future reuse; it does <emphasis>not</emphasis> attempt
to reclaim the space used by this dead data unless the space is
2005-12-07 15:35:45 +01:00
at the end of the table and an exclusive table lock can be easily
obtained. Unused space at the start or middle of the file does
not result in the file being shortened and space returned to the
operating system. This variant of <command>VACUUM</command> can be
run concurrently with normal database operations.
</para>
<para>
The second form is the <command>VACUUM FULL</command>
command. This uses a more aggressive algorithm for reclaiming the
space consumed by dead row versions. Any space that is freed by
<command>VACUUM FULL</command> is immediately returned to the
operating system. Unfortunately, this variant of the
<command>VACUUM</command> command acquires an exclusive lock on
each table while <command>VACUUM FULL</command> is processing
it. Therefore, frequently using <command>VACUUM FULL</command> can
have an extremely negative effect on the performance of concurrent
database queries.
</para>
<para>
The standard form of <command>VACUUM</> is best used with the goal
of maintaining a fairly level steady-state usage of disk space. If
you need to return disk space to the operating system you can use
<command>VACUUM FULL</> &mdash; but what's the point of releasing disk
space that will only have to be allocated again soon? Moderately
frequent standard <command>VACUUM</> runs are a better approach
than infrequent <command>VACUUM FULL</> runs for maintaining
heavily-updated tables.
</para>
<para>
Recommended practice for most sites is to schedule a database-wide
<command>VACUUM</> once a day at a low-usage time of day,
supplemented by more frequent vacuuming of heavily-updated tables
if necessary. (Some installations with extremely high update rates
vacuum their busiest tables as often as once every few minutes.)
If you have multiple databases
in a cluster, don't forget to <command>VACUUM</command> each one;
the program <xref linkend="app-vacuumdb" endterm="app-vacuumdb-title">
might be helpful.
</para>
<para>
<command>VACUUM FULL</> is recommended for cases where you know
you have deleted the majority of rows in a table, so that the
steady-state size of the table can be shrunk substantially with
<command>VACUUM FULL</>'s more aggressive approach. Use plain
<command>VACUUM</>, not <command>VACUUM FULL</>, for routine
vacuuming for space recovery.
</para>
<para>
If you have a table whose entire contents are deleted on a periodic
basis, consider doing it with <command>TRUNCATE</command> rather
than using <command>DELETE</command> followed by
<command>VACUUM</command>. <command>TRUNCATE</command> removes the
2004-12-13 19:05:10 +01:00
entire content of the table immediately, without requiring a
subsequent <command>VACUUM</command> or <command>VACUUM
FULL</command> to reclaim the now-unused disk space.
</para>
</sect2>
<sect2 id="vacuum-for-statistics">
<title>Updating planner statistics</title>
2003-08-31 19:32:24 +02:00
<indexterm zone="vacuum-for-statistics">
<primary>statistics</primary>
<secondary>of the planner</secondary>
</indexterm>
<indexterm zone="vacuum-for-statistics">
<primary>ANALYZE</primary>
</indexterm>
<para>
The <productname>PostgreSQL</productname> query planner relies on
statistical information about the contents of tables in order to
generate good plans for queries. These statistics are gathered by
the <command>ANALYZE</> command, which can be invoked by itself or
as an optional step in <command>VACUUM</>. It is important to have
reasonably accurate statistics, otherwise poor choices of plans might
degrade database performance.
</para>
<para>
As with vacuuming for space recovery, frequent updates of statistics
are more useful for heavily-updated tables than for seldom-updated
ones. But even for a heavily-updated table, there might be no need for
statistics updates if the statistical distribution of the data is
not changing much. A simple rule of thumb is to think about how much
the minimum and maximum values of the columns in the table change.
For example, a <type>timestamp</type> column that contains the time
of row update will have a constantly-increasing maximum value as
rows are added and updated; such a column will probably need more
frequent statistics updates than, say, a column containing URLs for
pages accessed on a website. The URL column might receive changes just
as often, but the statistical distribution of its values probably
changes relatively slowly.
</para>
<para>
It is possible to run <command>ANALYZE</> on specific tables and even
just specific columns of a table, so the flexibility exists to update some
statistics more frequently than others if your application requires it.
In practice, however, it is usually best to just analyze the entire database
because it is a fast operation. It uses a statistical random sampling of
the rows of a table rather than reading every single row.
</para>
<tip>
<para>
Although per-column tweaking of <command>ANALYZE</> frequency might not be
very productive, you might well find it worthwhile to do per-column
adjustment of the level of detail of the statistics collected by
<command>ANALYZE</>. Columns that are heavily used in <literal>WHERE</> clauses
and have highly irregular data distributions might require a finer-grain
data histogram than other columns. See <command>ALTER TABLE SET
STATISTICS</>.
</para>
</tip>
<para>
Recommended practice for most sites is to schedule a database-wide
<command>ANALYZE</> once a day at a low-usage time of day; this can
usefully be combined with a nightly <command>VACUUM</>. However,
sites with relatively slowly changing table statistics might find that
this is overkill, and that less-frequent <command>ANALYZE</> runs
are sufficient.
</para>
</sect2>
<sect2 id="vacuum-for-wraparound">
<title>Preventing transaction ID wraparound failures</title>
2001-11-12 20:19:39 +01:00
<indexterm zone="vacuum-for-wraparound">
<primary>transaction ID</primary>
<secondary>wraparound</secondary>
</indexterm>
<para>
<productname>PostgreSQL</productname>'s MVCC transaction semantics
depend on being able to compare transaction ID (<acronym>XID</>)
numbers: a row version with an insertion XID greater than the current
transaction's XID is <quote>in the future</> and should not be visible
to the current transaction. But since transaction IDs have limited size
(32 bits at this writing) a cluster that runs for a long time (more
than 4 billion transactions) would suffer <firstterm>transaction ID
wraparound</>: the XID counter wraps around to zero, and all of a sudden
transactions that were in the past appear to be in the future &mdash; which
2001-08-28 01:42:34 +02:00
means their outputs become invisible. In short, catastrophic data loss.
(Actually the data is still there, but that's cold comfort if you cannot
get at it.) To avoid this, it is necessary to vacuum every table
in every database at least once every two billion transactions.
</para>
<para>
The reason that periodic vacuuming solves the problem is that
<productname>PostgreSQL</productname> distinguishes a special XID
<literal>FrozenXID</>. This XID is always considered older
than every normal XID. Normal XIDs are
compared using modulo-2<superscript>31</> arithmetic. This means
that for every normal XID, there are two billion XIDs that are
<quote>older</> and two billion that are <quote>newer</>; another
way to say it is that the normal XID space is circular with no
endpoint. Therefore, once a row version has been created with a particular
normal XID, the row version will appear to be <quote>in the past</> for
the next two billion transactions, no matter which normal XID we are
talking about. If the row version still exists after more than two billion
transactions, it will suddenly appear to be in the future. To
prevent data loss, old row versions must be reassigned the XID
<literal>FrozenXID</> sometime before they reach the
two-billion-transactions-old mark. Once they are assigned this
special XID, they will appear to be <quote>in the past</> to all
normal transactions regardless of wraparound issues, and so such
row versions will be good until deleted, no matter how long that is.
This reassignment of old XIDs is handled by <command>VACUUM</>.
</para>
<para>
<command>VACUUM</>'s behavior is controlled by the configuration parameter
<xref linkend="guc-vacuum-freeze-min-age">: any XID older than
<varname>vacuum_freeze_min_age</> transactions is replaced by
<literal>FrozenXID</>. Larger values of <varname>vacuum_freeze_min_age</>
preserve transactional information longer, while smaller values increase
the number of transactions that can elapse before the table must be
vacuumed again.
</para>
<para>
The maximum time that a table can go unvacuumed is two billion
transactions minus the <varname>vacuum_freeze_min_age</> that was used
when it was last vacuumed.
If it were to go unvacuumed for longer than that,
data loss could result. To ensure that this does not
happen, the <firstterm>autovacuum</> facility described in
<xref linkend="autovacuum"> is invoked on any table
that might contain XIDs older than the age specified by the
configuration parameter
<xref linkend="guc-autovacuum-freeze-max-age">. (This will happen
even if autovacuum is otherwise disabled.)
</para>
<para>
This implies that if a table is not otherwise vacuumed,
autovacuum will be invoked on it approximately once every
<varname>autovacuum_freeze_max_age</> minus
<varname>vacuum_freeze_min_age</> transactions.
For tables that are regularly vacuumed for space reclamation purposes,
this is of little importance. However, for static tables
(including tables that receive inserts, but no updates or deletes),
there is no need for vacuuming for space reclamation, and so it can
be useful to try to maximize the interval between forced autovacuums
on very large static tables. Obviously one can do this either by
increasing <varname>autovacuum_freeze_max_age</> or by decreasing
<varname>vacuum_freeze_min_age</>.
</para>
<para>
The sole disadvantage of increasing <varname>autovacuum_freeze_max_age</>
is that the <filename>pg_clog</> subdirectory of the database cluster
will take more space, because it must store the commit status for all
transactions back to the <varname>autovacuum_freeze_max_age</> horizon.
The commit status uses two bits per transaction, so if
<varname>autovacuum_freeze_max_age</> has its maximum allowed value of
a little less than two billion, <filename>pg_clog</> can be expected to
grow to about half a gigabyte. If this is trivial compared to your
total database size, setting <varname>autovacuum_freeze_max_age</> to
its maximum allowed value is recommended. Otherwise, set it depending
on what you are willing to allow for <filename>pg_clog</> storage.
(The default, 200 million transactions, translates to about 50MB of
<filename>pg_clog</> storage.)
</para>
<para>
One disadvantage of decreasing <varname>vacuum_freeze_min_age</> is that
it might cause <command>VACUUM</> to do useless work: changing a table row's
XID to <literal>FrozenXID</> is a waste of time if the row is modified
soon thereafter (causing it to acquire a new XID). So the setting should
be large enough that rows are not frozen until they are unlikely to change
any more. Another disadvantage of decreasing this setting is
that details about exactly which transaction inserted or modified a
row will be lost sooner. This information sometimes comes in handy,
particularly when trying to analyze what went wrong after a database
failure. For these two reasons, decreasing this setting is not
recommended except for completely static tables.
</para>
<para>
To track the age of the oldest XIDs in a database,
<command>VACUUM</> stores XID
statistics in the system tables <structname>pg_class</> and
<structname>pg_database</>. In particular,
the <structfield>relfrozenxid</> column of a table's
<structname>pg_class</> row contains the freeze cutoff XID that was used
by the last <command>VACUUM</> for that table. All normal
XIDs older than this cutoff XID are guaranteed to have been replaced by
<literal>FrozenXID</> within the table. Similarly,
the <structfield>datfrozenxid</> column of a database's
<structname>pg_database</> row is a lower bound on the normal XIDs
appearing in that database &mdash; it is just the minimum of the
per-table <structfield>relfrozenxid</> values within the database.
A convenient way to
examine this information is to execute queries such as:
<programlisting>
SELECT relname, age(relfrozenxid) FROM pg_class WHERE relkind = 'r';
2001-10-13 01:32:34 +02:00
SELECT datname, age(datfrozenxid) FROM pg_database;
</programlisting>
The <literal>age</> column measures the number of transactions from the
cutoff XID to the current transaction's XID. Immediately after a
<command>VACUUM</>, <literal>age(relfrozenxid)</> should be a little
more than the <varname>vacuum_freeze_min_age</> setting that was used
(more by the number of transactions started since the <command>VACUUM</>
started). If <literal>age(relfrozenxid)</> exceeds
<varname>autovacuum_freeze_max_age</>, an autovacuum will soon be forced
for the table.
</para>
<para>
If for some reason autovacuum fails to clear old XIDs from a table,
the system will begin to emit warning messages like this when the
database's oldest XIDs reach ten million transactions from the wraparound
point:
<programlisting>
WARNING: database "mydb" must be vacuumed within 177009986 transactions
HINT: To avoid a database shutdown, execute a full-database VACUUM in "mydb".
</programlisting>
If these warnings are
ignored, the system will shut down and refuse to execute any new
transactions once there are fewer than 1 million transactions left
until wraparound:
<programlisting>
ERROR: database is shut down to avoid wraparound data loss in database "mydb"
HINT: Stop the postmaster and use a standalone backend to VACUUM in "mydb".
</programlisting>
The 1-million-transaction safety margin exists to let the
administrator recover without data loss, by manually executing the
required <command>VACUUM</> commands. However, since the system will not
execute commands once it has gone into the safety shutdown mode,
the only way to do this is to stop the server and use a single-user
backend to execute <command>VACUUM</>. The shutdown mode is not enforced
by a single-user backend. See the <xref linkend="app-postgres"> reference
page for details about using a single-user backend.
</para>
</sect2>
2005-09-13 03:51:18 +02:00
<sect2 id="autovacuum">
<title id="autovacuum-title">The auto-vacuum daemon</title>
2005-09-13 03:51:18 +02:00
<indexterm>
<primary>autovacuum</primary>
<secondary>general information</secondary>
</indexterm>
<para>
Beginning in <productname>PostgreSQL</productname> 8.1, there is an
optional feature called <firstterm>autovacuum</firstterm>,
whose purpose is to automate the execution of
2005-09-13 03:51:18 +02:00
<command>VACUUM</command> and <command>ANALYZE </command> commands.
When enabled, autovacuum checks for
2005-09-13 03:51:18 +02:00
tables that have had a large number of inserted, updated or deleted
tuples. These checks use the row-level statistics collection facility;
therefore, autovacuum cannot be used unless <xref
2005-09-13 03:51:18 +02:00
linkend="guc-stats-start-collector"> and <xref
linkend="guc-stats-row-level"> are set to <literal>true</literal>.
In the default configuration, autovacuuming is enabled and the related
configuration parameters are appropriately set.
2005-09-13 03:51:18 +02:00
</para>
<para>
Beginning in <productname>PostgreSQL</productname> 8.3, autovacuum has a
multi-process architecture: there is a daemon process, called the
<firstterm>autovacuum launcher</firstterm>, which is in charge of starting
an <firstterm>autovacuum worker</firstterm> process on each database every
<xref linkend="guc-autovacuum-naptime"> seconds.
</para>
<para>
There is a limit of <xref linkend="guc-autovacuum-max-workers"> worker
processes that may be running at at any time, so if the <command>VACUUM</>
and <command>ANALYZE</> work to do takes too long to run, the deadline may
be failed to meet for other databases. Also, if a particular database
takes long to process, more than one worker may be processing it
simultaneously. The workers are smart enough to avoid repeating work that
other workers have done, so this is normally not a problem. Note that the
number of running workers does not count towards the <xref
linkend="guc-max-connections"> nor the <xref
linkend="guc-superuser-reserved-connections"> limits.
</para>
<para>
On each run, the worker process checks each table within that database, and
<command>VACUUM</command> or <command>ANALYZE</command> commands are
issued as needed.
2005-09-13 03:51:18 +02:00
</para>
<para>
Tables whose <structfield>relfrozenxid</> value is more than
<varname>autovacuum_freeze_max_age</> transactions old are always
vacuumed. Otherwise,
two conditions are used to determine which operation(s)
to apply. If the number of obsolete tuples since the last
2005-09-13 03:51:18 +02:00
<command>VACUUM</command> exceeds the <quote>vacuum threshold</quote>, the
table is vacuumed. The vacuum threshold is defined as:
2005-09-13 03:51:18 +02:00
<programlisting>
vacuum threshold = vacuum base threshold + vacuum scale factor * number of tuples
</programlisting>
where the vacuum base threshold is
<xref linkend="guc-autovacuum-vacuum-threshold">,
2005-09-13 03:51:18 +02:00
the vacuum scale factor is
<xref linkend="guc-autovacuum-vacuum-scale-factor">,
2005-09-13 03:51:18 +02:00
and the number of tuples is
<structname>pg_class</structname>.<structfield>reltuples</structfield>.
The number of obsolete tuples is obtained from the statistics
collector; it is a semi-accurate count updated by each
2005-09-13 03:51:18 +02:00
<command>UPDATE</command> and <command>DELETE</command> operation. (It
is only semi-accurate because some information might be lost under heavy
load.) For analyze, a similar condition is used: the threshold, defined as:
<programlisting>
analyze threshold = analyze base threshold + analyze scale factor * number of tuples
</programlisting>
is compared to the total number of tuples inserted, updated, or deleted
since the last <command>ANALYZE</command>.
2005-09-13 03:51:18 +02:00
</para>
<para>
The default thresholds and scale factors are taken from
<filename>postgresql.conf</filename>, but it is possible to override them
on a table-by-table basis by making entries in the system catalog
<link
linkend="catalog-pg-autovacuum"><structname>pg_autovacuum</></link>.
If a <structname>pg_autovacuum</structname> row exists for a particular
table, the settings it specifies are applied; otherwise the global
settings are used. See <xref linkend="runtime-config-autovacuum"> for
more details on the global settings.
2005-09-13 03:51:18 +02:00
</para>
<para>
Besides the base threshold values and scale factors, there are five
more parameters that can be set for each table in
<structname>pg_autovacuum</structname>.
The first, <structname>pg_autovacuum</>.<structfield>enabled</>,
can be set to <literal>false</literal> to instruct the autovacuum daemon
to skip that particular table entirely. In this case
autovacuum will only touch the table if it must do so
to prevent transaction ID wraparound.
The next two parameters, the vacuum cost delay
2005-09-13 03:51:18 +02:00
(<structname>pg_autovacuum</structname>.<structfield>vac_cost_delay</structfield>)
and the vacuum cost limit
(<structname>pg_autovacuum</structname>.<structfield>vac_cost_limit</structfield>),
are used to set table-specific values for the
2005-09-13 03:51:18 +02:00
<xref linkend="runtime-config-resource-vacuum-cost" endterm="runtime-config-resource-vacuum-cost-title">
feature.
The last two parameters,
(<structname>pg_autovacuum</structname>.<structfield>freeze_min_age</structfield>)
and
(<structname>pg_autovacuum</structname>.<structfield>freeze_max_age</structfield>),
are used to set table-specific values for
<xref linkend="guc-vacuum-freeze-min-age"> and
<xref linkend="guc-autovacuum-freeze-max-age"> respectively.
2005-09-13 03:51:18 +02:00
</para>
<para>
If any of the values in <structname>pg_autovacuum</structname>
are set to a negative number, or if a row is not present at all in
<structname>pg_autovacuum</structname> for any particular table, the
corresponding values from <filename>postgresql.conf</filename> are used.
</para>
<para>
There is not currently any support for making
<structname>pg_autovacuum</structname> entries, except by doing
manual <command>INSERT</>s into the catalog. This feature will be
improved in future releases, and it is likely that the catalog
definition will change.
</para>
<caution>
<para>
The contents of the <structname>pg_autovacuum</structname> system
catalog are currently not saved in database dumps created by
the tools <command>pg_dump</command> and <command>pg_dumpall</command>.
If you want to preserve them across a dump/reload cycle, make sure you
dump the catalog manually.
</para>
</caution>
<para>
When multiple workers are running, the cost limit is "balanced" among all
the running workers, so that the total impact on the system is the same,
regardless of the number of workers actually running.
</para>
2005-09-13 03:51:18 +02:00
</sect2>
</sect1>
2002-06-13 06:36:50 +02:00
2002-06-22 06:08:07 +02:00
<sect1 id="routine-reindex">
<title>Routine Reindexing</title>
<indexterm zone="routine-reindex">
<primary>reindex</primary>
</indexterm>
<para>
In some situations it is worthwhile to rebuild indexes periodically
with the <xref linkend="sql-reindex" endterm="sql-reindex-title">
command.
</para>
<para>
In <productname>PostgreSQL</> releases before 7.4, periodic reindexing
was frequently necessary to avoid <quote>index bloat</>, due to lack of
2005-11-05 00:14:02 +01:00
internal space reclamation in B-tree indexes. Any situation in which the
range of index keys changed over time &mdash; for example, an index on
timestamps in a table where old entries are eventually deleted &mdash;
would result in bloat, because index pages for no-longer-needed portions
of the key range were not reclaimed for re-use. Over time, the index size
could become indefinitely much larger than the amount of useful data in it.
</para>
<para>
In <productname>PostgreSQL</> 7.4 and later, index pages that have become
completely empty are reclaimed for re-use. There is still a possibility
for inefficient use of space: if all but a few index keys on a page have
been deleted, the page remains allocated. So a usage pattern in which all
but a few keys in each range are eventually deleted will see poor use of
space. For such usage patterns, periodic reindexing is recommended.
</para>
<para>
2005-11-05 00:14:02 +01:00
The potential for bloat in non-B-tree indexes has not been well
characterized. It is a good idea to keep an eye on the index's physical
2005-11-05 00:14:02 +01:00
size when using any non-B-tree index type.
</para>
<para>
2005-11-05 00:14:02 +01:00
Also, for B-tree indexes a freshly-constructed index is somewhat faster to
access than one that has been updated many times, because logically
adjacent pages are usually also physically adjacent in a newly built index.
2005-11-05 00:14:02 +01:00
(This consideration does not currently apply to non-B-tree indexes.) It
might be worthwhile to reindex periodically just to improve access speed.
2002-06-22 06:08:07 +02:00
</para>
</sect1>
<sect1 id="logfile-maintenance">
<title>Log File Maintenance</title>
<indexterm zone="logfile-maintenance">
2003-08-31 19:32:24 +02:00
<primary>server log</primary>
<secondary>log file maintenance</secondary>
</indexterm>
<para>
It is a good idea to save the database server's log output
somewhere, rather than just routing it to <filename>/dev/null</>.
The log output is invaluable when it comes time to diagnose
problems. However, the log output tends to be voluminous
(especially at higher debug levels) and you won't want to save it
indefinitely. You need to <quote>rotate</> the log files so that
new log files are started and old ones removed after a reasonable
period of time.
</para>
<para>
If you simply direct the <systemitem>stderr</> of
<command>postgres</command> into a
file, you will have log output, but
the only way to truncate the log file is to stop and restart
the server. This might be OK if you are using
<productname>PostgreSQL</productname> in a development environment,
but few production servers would find this behavior acceptable.
</para>
<para>
A better approach is to send the server's
<systemitem>stderr</> output to some type of log rotation program.
There is a built-in log rotation program, which you can use by
setting the configuration parameter <literal>redirect_stderr</> to
<literal>true</> in <filename>postgresql.conf</>. The control
parameters for this program are described in <xref
linkend="runtime-config-logging-where">.
</para>
<para>
Alternatively, you might prefer to use an external log rotation
program, if you have one that you are already using with other
server software. For example, the <application>rotatelogs</application>
tool included in the <productname>Apache</productname> distribution
can be used with <productname>PostgreSQL</productname>. To do this,
just pipe the server's
<systemitem>stderr</> output to the desired program.
If you start the server with
<command>pg_ctl</>, then <systemitem>stderr</>
is already redirected to <systemitem>stdout</>, so you just need a
2004-12-27 23:30:10 +01:00
pipe command, for example:
<programlisting>
pg_ctl start | rotatelogs /var/log/pgsql_log 86400
</programlisting>
</para>
<para>
Another production-grade approach to managing log output is to
send it all to <application>syslog</> and let
<application>syslog</> deal with file rotation. To do this, set the
configuration parameter <literal>log_destination</> to <literal>syslog</>
(to log to <application>syslog</> only) in
<filename>postgresql.conf</>. Then you can send a <literal>SIGHUP</literal>
signal to the <application>syslog</> daemon whenever you want to force it
to start writing a new log file. If you want to automate log
rotation, the <application>logrotate</application> program can be
configured to work with log files from
<application>syslog</application>.
</para>
<para>
On many systems, however, <application>syslog</> is not very reliable,
particularly with large log messages; it might truncate or drop messages
2004-12-27 23:30:10 +01:00
just when you need them the most. Also, on <productname>Linux</>,
2004-03-15 15:21:30 +01:00
<application>syslog</> will sync each message to disk, yielding poor
performance. (You can use a <literal>-</> at the start of the file name
2004-12-13 19:05:10 +01:00
in the <application>syslog</> configuration file to disable this behavior.)
</para>
<para>
Note that all the solutions described above take care of starting new
log files at configurable intervals, but they do not handle deletion
2004-12-27 23:30:10 +01:00
of old, no-longer-interesting log files. You will probably want to set
up a batch job to periodically delete old log files. Another possibility
is to configure the rotation program so that old log files are overwritten
cyclically.
</para>
</sect1>
</chapter>