Fix xslt_process() to ensure that it inserts a NULL terminator after the
[PostgreSQL.git] / doc / src / sgml / maintenance.sgml
blobe9180a07c4eaa8fb40895947ea66f209850e4df1
1 <!-- $PostgreSQL$ -->
3 <chapter id="maintenance">
4 <title>Routine Database Maintenance Tasks</title>
6 <indexterm zone="maintenance">
7 <primary>maintenance</primary>
8 </indexterm>
10 <indexterm zone="maintenance">
11 <primary>routine maintenance</primary>
12 </indexterm>
14 <para>
15 <productname>PostgreSQL</>, like any database software, requires that certain tasks
16 be performed regularly to achieve optimum performance. The tasks
17 discussed here are <emphasis>required</emphasis>, but they
18 are repetitive in nature and can easily be automated using standard
19 tools such as <application>cron</application> scripts or
20 Windows' <application>Task Scheduler</>. But it is the database
21 administrator's responsibility to set up appropriate scripts, and to
22 check that they execute successfully.
23 </para>
25 <para>
26 One obvious maintenance task is creation of backup copies of the data on a
27 regular schedule. Without a recent backup, you have no chance of recovery
28 after a catastrophe (disk failure, fire, mistakenly dropping a critical
29 table, etc.). The backup and recovery mechanisms available in
30 <productname>PostgreSQL</productname> are discussed at length in
31 <xref linkend="backup">.
32 </para>
34 <para>
35 The other main category of maintenance task is periodic <quote>vacuuming</>
36 of the database. This activity is discussed in
37 <xref linkend="routine-vacuuming">. Closely related to this is updating
38 the statistics that will be used by the query planner, as discussed in
39 <xref linkend="vacuum-for-statistics">.
40 </para>
42 <para>
43 Another task that might need periodic attention is log file management.
44 This is discussed in <xref linkend="logfile-maintenance">.
45 </para>
47 <para>
48 <ulink
49 url="http://bucardo.org/check_postgres/"><application>check_postgres.pl</></ulink>
50 is available for monitoring database health and reporting unusual
51 conditions. <application>check_postgres.pl</> integrates with
52 Nagios and MRTG, but can be run standalone too.
53 </para>
55 <para>
56 <productname>PostgreSQL</productname> is low-maintenance compared
57 to some other database management systems. Nonetheless,
58 appropriate attention to these tasks will go far towards ensuring a
59 pleasant and productive experience with the system.
60 </para>
62 <sect1 id="routine-vacuuming">
63 <title>Routine Vacuuming</title>
65 <indexterm zone="routine-vacuuming">
66 <primary>vacuum</primary>
67 </indexterm>
69 <para>
70 <productname>PostgreSQL</productname> databases require periodic
71 maintenance known as <firstterm>vacuuming</>. For many installations, it
72 is sufficient to let vacuuming be performed by the <firstterm>autovacuum
73 daemon</>, which is described in <xref linkend="autovacuum">. You might
74 need to adjust the autovacuuming parameters described there to obtain best
75 results for your situation. Some database administrators will want to
76 supplement or replace the daemon's activities with manually-managed
77 <command>VACUUM</> commands, which typically are executed according to a
78 schedule by <application>cron</application> or <application>Task
79 Scheduler</> scripts. To set up manually-managed vacuuming properly,
80 it is essential to understand the issues discussed in the next few
81 subsections. Administrators who rely on autovacuuming may still wish
82 to skim this material to help them understand and adjust autovacuuming.
83 </para>
85 <sect2 id="vacuum-basics">
86 <title>Vacuuming Basics</title>
88 <para>
89 <productname>PostgreSQL</productname>'s
90 <xref linkend="sql-vacuum" endterm="sql-vacuum-title"> command has to
91 process each table on a regular basis for several reasons:
93 <orderedlist>
94 <listitem>
95 <simpara>To recover or reuse disk space occupied by updated or deleted
96 rows.</simpara>
97 </listitem>
99 <listitem>
100 <simpara>To update data statistics used by the
101 <productname>PostgreSQL</productname> query planner.</simpara>
102 </listitem>
104 <listitem>
105 <simpara>To protect against loss of very old data due to
106 <firstterm>transaction ID wraparound</>.</simpara>
107 </listitem>
108 </orderedlist>
110 Each of these reasons dictates performing <command>VACUUM</> operations
111 of varying frequency and scope, as explained in the following subsections.
112 </para>
114 <para>
115 There are two variants of <command>VACUUM</>: standard <command>VACUUM</>
116 and <command>VACUUM FULL</>. <command>VACUUM FULL</> can reclaim more
117 disk space but runs much more slowly. Also,
118 the standard form of <command>VACUUM</> can run in parallel with production
119 database operations. (Commands such as <command>SELECT</command>,
120 <command>INSERT</command>, <command>UPDATE</command>, and
121 <command>DELETE</command> will continue to function as normal, though you
122 will not be able to modify the definition of a table with commands such as
123 <command>ALTER TABLE</command> while it is being vacuumed.)
124 <command>VACUUM FULL</> requires exclusive lock on the table it is
125 working on, and therefore cannot be done in parallel with other use
126 of the table. Another disadvantage of <command>VACUUM FULL</> is that
127 while it reduces table size, it does not reduce index size proportionally;
128 in fact it can make indexes <emphasis>larger</>. Generally, therefore,
129 administrators should strive to use standard <command>VACUUM</> and
130 avoid <command>VACUUM FULL</>.
131 </para>
133 <para>
134 <command>VACUUM</command> creates a substantial amount of I/O
135 traffic, which can cause poor performance for other active sessions.
136 There are configuration parameters that can be adjusted to reduce the
137 performance impact of background vacuuming &mdash; see
138 <xref linkend="runtime-config-resource-vacuum-cost">.
139 </para>
140 </sect2>
142 <sect2 id="vacuum-for-space-recovery">
143 <title>Recovering Disk Space</title>
145 <indexterm zone="vacuum-for-space-recovery">
146 <primary>disk space</primary>
147 </indexterm>
149 <para>
150 In <productname>PostgreSQL</productname>, an
151 <command>UPDATE</> or <command>DELETE</> of a row does not
152 immediately remove the old version of the row.
153 This approach is necessary to gain the benefits of multiversion
154 concurrency control (see <xref linkend="mvcc">): the row version
155 must not be deleted while it is still potentially visible to other
156 transactions. But eventually, an outdated or deleted row version is no
157 longer of interest to any transaction. The space it occupies must then be
158 reclaimed for reuse by new rows, to avoid infinite growth of disk
159 space requirements. This is done by running <command>VACUUM</>.
160 </para>
162 <para>
163 The standard form of <command>VACUUM</command> removes dead row
164 versions in tables and indexes and marks the space available for
165 future reuse. However, it will not return the space to the operating
166 system, except in the special case where one or more pages at the
167 end of a table become entirely free and an exclusive table lock can be
168 easily obtained. In contrast, <command>VACUUM FULL</> actively compacts
169 tables by moving row versions to earlier pages. It is thus able to
170 force pages at the end of the table to become entirely free, whereupon
171 it will return them to the operating system. However, if many rows
172 must be moved, this can take a long time. Also, moving a row requires
173 transiently making duplicate index entries for it (the entry pointing
174 to its new location must be made before the old entry can be removed);
175 so moving a lot of rows this way causes severe index bloat.
176 </para>
178 <para>
179 The usual goal of routine vacuuming is to do standard <command>VACUUM</>s
180 often enough to avoid needing <command>VACUUM FULL</>. The
181 autovacuum daemon attempts to work this way, and in fact will
182 never issue <command>VACUUM FULL</>. In this approach, the idea
183 is not to keep tables at their minimum size, but to maintain steady-state
184 usage of disk space: each table occupies space equivalent to its
185 minimum size plus however much space gets used up between vacuumings.
186 Although <command>VACUUM FULL</> can be used to shrink a table back
187 to its minimum size and return the disk space to the operating system,
188 there is not much point in this if the table will just grow again in the
189 future. Thus, moderately-frequent standard <command>VACUUM</> runs are a
190 better approach than infrequent <command>VACUUM FULL</> runs for
191 maintaining heavily-updated tables.
192 </para>
194 <para>
195 Some administrators prefer to schedule vacuuming themselves, for example
196 doing all the work at night when load is low.
197 The difficulty with doing vacuuming according to a fixed schedule
198 is that if a table has an unexpected spike in update activity, it may
199 get bloated to the point that <command>VACUUM FULL</> is really necessary
200 to reclaim space. Using the autovacuum daemon alleviates this problem,
201 since the daemon schedules vacuuming dynamically in response to update
202 activity. It is unwise to disable the daemon completely unless you
203 have an extremely predictable workload. One possible compromise is
204 to set the daemon's parameters so that it will only react to unusually
205 heavy update activity, thus keeping things from getting out of hand,
206 while scheduled <command>VACUUM</>s are expected to do the bulk of the
207 work when the load is typical.
208 </para>
210 <para>
211 For those not using autovacuum, a typical approach is to schedule a
212 database-wide <command>VACUUM</> once a day during a low-usage period,
213 supplemented by more frequent vacuuming of heavily-updated tables as
214 necessary. (Some installations with extremely high update rates vacuum
215 their busiest tables as often as once every few minutes.) If you have
216 multiple databases in a cluster, don't forget to
217 <command>VACUUM</command> each one; the program <xref
218 linkend="app-vacuumdb" endterm="app-vacuumdb-title"> might be helpful.
219 </para>
221 <tip>
222 <para>
223 Neither form of <command>VACUUM</> is entirely satisfactory when
224 a table contains large numbers of dead row versions as a result of
225 massive update or delete activity. If you have such a table and
226 you need to reclaim the excess disk space it occupies, the best
227 way is to use <xref linkend="sql-cluster" endterm="sql-cluster-title">
228 or one of the table-rewriting variants of
229 <xref linkend="sql-altertable" endterm="sql-altertable-title">.
230 These commands rewrite an entire new copy of the table and build
231 new indexes for it. Like <command>VACUUM FULL</>, they require
232 exclusive lock. Note that they also temporarily use extra disk
233 space, since the old copies of the table and indexes can't be
234 released until the new ones are complete. In the worst case where
235 your disk is nearly full, <command>VACUUM FULL</> may be the only
236 workable alternative.
237 </para>
238 </tip>
240 <tip>
241 <para>
242 If you have a table whose entire contents are deleted on a periodic
243 basis, consider doing it with
244 <xref linkend="sql-truncate" endterm="sql-truncate-title"> rather
245 than using <command>DELETE</command> followed by
246 <command>VACUUM</command>. <command>TRUNCATE</command> removes the
247 entire content of the table immediately, without requiring a
248 subsequent <command>VACUUM</command> or <command>VACUUM
249 FULL</command> to reclaim the now-unused disk space.
250 The disadvantage is that strict MVCC semantics are violated.
251 </para>
252 </tip>
253 </sect2>
255 <sect2 id="vacuum-for-statistics">
256 <title>Updating Planner Statistics</title>
258 <indexterm zone="vacuum-for-statistics">
259 <primary>statistics</primary>
260 <secondary>of the planner</secondary>
261 </indexterm>
263 <indexterm zone="vacuum-for-statistics">
264 <primary>ANALYZE</primary>
265 </indexterm>
267 <para>
268 The <productname>PostgreSQL</productname> query planner relies on
269 statistical information about the contents of tables in order to
270 generate good plans for queries. These statistics are gathered by
271 the <xref linkend="sql-analyze" endterm="sql-analyze-title"> command,
272 which can be invoked by itself or
273 as an optional step in <command>VACUUM</>. It is important to have
274 reasonably accurate statistics, otherwise poor choices of plans might
275 degrade database performance.
276 </para>
278 <para>
279 The autovacuum daemon, if enabled, will automatically issue
280 <command>ANALYZE</> commands whenever the content of a table has
281 changed sufficiently. However, administrators might prefer to rely
282 on manually-scheduled <command>ANALYZE</> operations, particularly
283 if it is known that update activity on a table will not affect the
284 statistics of <quote>interesting</> columns. The daemon schedules
285 <command>ANALYZE</> strictly as a function of the number of rows
286 inserted or updated; it has no knowledge of whether that will lead
287 to meaningful statistical changes.
288 </para>
290 <para>
291 As with vacuuming for space recovery, frequent updates of statistics
292 are more useful for heavily-updated tables than for seldom-updated
293 ones. But even for a heavily-updated table, there might be no need for
294 statistics updates if the statistical distribution of the data is
295 not changing much. A simple rule of thumb is to think about how much
296 the minimum and maximum values of the columns in the table change.
297 For example, a <type>timestamp</type> column that contains the time
298 of row update will have a constantly-increasing maximum value as
299 rows are added and updated; such a column will probably need more
300 frequent statistics updates than, say, a column containing URLs for
301 pages accessed on a website. The URL column might receive changes just
302 as often, but the statistical distribution of its values probably
303 changes relatively slowly.
304 </para>
306 <para>
307 It is possible to run <command>ANALYZE</> on specific tables and even
308 just specific columns of a table, so the flexibility exists to update some
309 statistics more frequently than others if your application requires it.
310 In practice, however, it is usually best to just analyze the entire
311 database, because it is a fast operation. <command>ANALYZE</> uses a
312 statistical random sampling of the rows of a table rather than reading
313 every single row.
314 </para>
316 <tip>
317 <para>
318 Although per-column tweaking of <command>ANALYZE</> frequency might not be
319 very productive, you might well find it worthwhile to do per-column
320 adjustment of the level of detail of the statistics collected by
321 <command>ANALYZE</>. Columns that are heavily used in <literal>WHERE</>
322 clauses and have highly irregular data distributions might require a
323 finer-grain data histogram than other columns. See <command>ALTER TABLE
324 SET STATISTICS</>, or change the database-wide default using the <xref
325 linkend="guc-default-statistics-target"> configuration parameter.
326 </para>
327 </tip>
328 </sect2>
330 <sect2 id="vacuum-for-wraparound">
331 <title>Preventing Transaction ID Wraparound Failures</title>
333 <indexterm zone="vacuum-for-wraparound">
334 <primary>transaction ID</primary>
335 <secondary>wraparound</secondary>
336 </indexterm>
338 <para>
339 <productname>PostgreSQL</productname>'s MVCC transaction semantics
340 depend on being able to compare transaction ID (<acronym>XID</>)
341 numbers: a row version with an insertion XID greater than the current
342 transaction's XID is <quote>in the future</> and should not be visible
343 to the current transaction. But since transaction IDs have limited size
344 (32 bits at this writing) a cluster that runs for a long time (more
345 than 4 billion transactions) would suffer <firstterm>transaction ID
346 wraparound</>: the XID counter wraps around to zero, and all of a sudden
347 transactions that were in the past appear to be in the future &mdash; which
348 means their outputs become invisible. In short, catastrophic data loss.
349 (Actually the data is still there, but that's cold comfort if you cannot
350 get at it.) To avoid this, it is necessary to vacuum every table
351 in every database at least once every two billion transactions.
352 </para>
354 <para>
355 The reason that periodic vacuuming solves the problem is that
356 <productname>PostgreSQL</productname> distinguishes a special XID
357 <literal>FrozenXID</>. This XID is always considered older
358 than every normal XID. Normal XIDs are
359 compared using modulo-2<superscript>31</> arithmetic. This means
360 that for every normal XID, there are two billion XIDs that are
361 <quote>older</> and two billion that are <quote>newer</>; another
362 way to say it is that the normal XID space is circular with no
363 endpoint. Therefore, once a row version has been created with a particular
364 normal XID, the row version will appear to be <quote>in the past</> for
365 the next two billion transactions, no matter which normal XID we are
366 talking about. If the row version still exists after more than two billion
367 transactions, it will suddenly appear to be in the future. To
368 prevent data loss, old row versions must be reassigned the XID
369 <literal>FrozenXID</> sometime before they reach the
370 two-billion-transactions-old mark. Once they are assigned this
371 special XID, they will appear to be <quote>in the past</> to all
372 normal transactions regardless of wraparound issues, and so such
373 row versions will be good until deleted, no matter how long that is.
374 This reassignment of old XIDs is handled by <command>VACUUM</>.
375 </para>
377 <para>
378 <xref linkend="guc-vacuum-freeze-min-age">
379 controls how old an XID value has to be before it's replaced with
380 <literal>FrozenXID</>. Larger values of this setting
381 preserve transactional information longer, while smaller values increase
382 the number of transactions that can elapse before the table must be
383 vacuumed again.
384 </para>
386 <para>
387 <command>VACUUM</> normally skips pages that don't have any dead row
388 versions, but those pages might still have row versions with old XID
389 values. To ensure all old XIDs have been replaced by
390 <literal>FrozenXID</>, a scan of the whole table is needed.
391 <xref linkend="guc-vacuum-freeze-table-age"> controls when
392 <command>VACUUM</> does that: a whole table sweep is forced if
393 the table hasn't been fully scanned for <varname>vacuum_freeze_table_age</>
394 minus <varname>vacuum_freeze_min_age</> transactions. Setting it to 0
395 forces <command>VACUUM</> to always scan all pages, effectively ignoring
396 the visibility map.
397 </para>
399 <para>
400 The maximum time that a table can go unvacuumed is two billion
401 transactions minus the <varname>vacuum_freeze_min_age</> that was used
402 when <command>VACUUM</> last scanned the whole table. If it were to go
403 unvacuumed for longer than
404 that, data loss could result. To ensure that this does not happen,
405 autovacuum is invoked on any table that might contain XIDs older than the
406 age specified by the configuration parameter <xref
407 linkend="guc-autovacuum-freeze-max-age">. (This will happen even if
408 autovacuum is otherwise disabled.)
409 </para>
411 <para>
412 This implies that if a table is not otherwise vacuumed,
413 autovacuum will be invoked on it approximately once every
414 <varname>autovacuum_freeze_max_age</> minus
415 <varname>vacuum_freeze_min_age</> transactions.
416 For tables that are regularly vacuumed for space reclamation purposes,
417 this is of little importance. However, for static tables
418 (including tables that receive inserts, but no updates or deletes),
419 there is no need for vacuuming for space reclamation, and so it can
420 be useful to try to maximize the interval between forced autovacuums
421 on very large static tables. Obviously one can do this either by
422 increasing <varname>autovacuum_freeze_max_age</> or by decreasing
423 <varname>vacuum_freeze_min_age</>.
424 </para>
426 <para>
427 The effective maximum for <varname>vacuum_freeze_table_age</> is 0.95 *
428 <varname>autovacuum_freeze_max_age</>; a setting higher than that will be
429 capped to the maximum. A value higher than
430 <varname>autovacuum_freeze_max_age</> wouldn't make sense because an
431 anti-wraparound autovacuum would be triggered at that point anyway, and
432 the 0.95 multiplier leaves some breathing room to run a manual
433 <command>VACUUM</> before that happens. As a rule of thumb,
434 <command>vacuum_freeze_table_age</> should be set to a value somewhat
435 below <varname>autovacuum_freeze_max_age</>, leaving enough gap so that
436 a regularly scheduled <command>VACUUM</> or an autovacuum triggered by
437 normal delete and update activity is run in that window. Setting it too
438 close could lead to anti-wraparound autovacuums, even though the table
439 was recently vacuumed to reclaim space, whereas lower values lead to more
440 frequent whole-table scans.
441 </para>
443 <para>
444 The sole disadvantage of increasing <varname>autovacuum_freeze_max_age</>
445 (and <varname>vacuum_freeze_table_age</> along with it)
446 is that the <filename>pg_clog</> subdirectory of the database cluster
447 will take more space, because it must store the commit status for all
448 transactions back to the <varname>autovacuum_freeze_max_age</> horizon.
449 The commit status uses two bits per transaction, so if
450 <varname>autovacuum_freeze_max_age</> has its maximum allowed value of
451 a little less than two billion, <filename>pg_clog</> can be expected to
452 grow to about half a gigabyte. If this is trivial compared to your
453 total database size, setting <varname>autovacuum_freeze_max_age</> to
454 its maximum allowed value is recommended. Otherwise, set it depending
455 on what you are willing to allow for <filename>pg_clog</> storage.
456 (The default, 200 million transactions, translates to about 50MB of
457 <filename>pg_clog</> storage.)
458 </para>
460 <para>
461 One disadvantage of decreasing <varname>vacuum_freeze_min_age</> is that
462 it might cause <command>VACUUM</> to do useless work: changing a table row's
463 XID to <literal>FrozenXID</> is a waste of time if the row is modified
464 soon thereafter (causing it to acquire a new XID). So the setting should
465 be large enough that rows are not frozen until they are unlikely to change
466 any more. Another disadvantage of decreasing this setting is
467 that details about exactly which transaction inserted or modified a
468 row will be lost sooner. This information sometimes comes in handy,
469 particularly when trying to analyze what went wrong after a database
470 failure. For these two reasons, decreasing this setting is not
471 recommended except for completely static tables.
472 </para>
474 <para>
475 To track the age of the oldest XIDs in a database,
476 <command>VACUUM</> stores XID
477 statistics in the system tables <structname>pg_class</> and
478 <structname>pg_database</>. In particular,
479 the <structfield>relfrozenxid</> column of a table's
480 <structname>pg_class</> row contains the freeze cutoff XID that was used
481 by the last whole-table <command>VACUUM</> for that table. All normal
482 XIDs older than this cutoff XID are guaranteed to have been replaced by
483 <literal>FrozenXID</> within the table. Similarly,
484 the <structfield>datfrozenxid</> column of a database's
485 <structname>pg_database</> row is a lower bound on the normal XIDs
486 appearing in that database &mdash; it is just the minimum of the
487 per-table <structfield>relfrozenxid</> values within the database.
488 A convenient way to
489 examine this information is to execute queries such as:
491 <programlisting>
492 SELECT relname, age(relfrozenxid) FROM pg_class WHERE relkind = 'r';
493 SELECT datname, age(datfrozenxid) FROM pg_database;
494 </programlisting>
496 The <literal>age</> column measures the number of transactions from the
497 cutoff XID to the current transaction's XID.
498 </para>
500 <para>
501 <command>VACUUM</> normally
502 only scans pages that have been modified since the last vacuum, but
503 <structfield>relfrozenxid</> can only be advanced when the whole table is
504 scanned. The whole table is scanned when <structfield>relfrozenxid</> is
505 more than <varname>vacuum_freeze_table_age</> transactions old, when the
506 <command>VACUUM FREEZE</> command is used, or when all pages happen to
507 require vacuuming to remove dead row versions. When <command>VACUUM</>
508 scans the whole table, after it's finished <literal>age(relfrozenxid)</>
509 should be a little more than the <varname>vacuum_freeze_min_age</> setting
510 that was used (more by the number of transactions started since the
511 <command>VACUUM</> started). If no whole-table-scanning <command>VACUUM</>
512 is issued on the table until <varname>autovacuum_freeze_max_age</> is
513 reached, an autovacuum will soon be forced for the table.
514 </para>
516 <para>
517 If for some reason autovacuum fails to clear old XIDs from a table,
518 the system will begin to emit warning messages like this when the
519 database's oldest XIDs reach ten million transactions from the wraparound
520 point:
522 <programlisting>
523 WARNING: database "mydb" must be vacuumed within 177009986 transactions
524 HINT: To avoid a database shutdown, execute a database-wide VACUUM in "mydb".
525 </programlisting>
527 (A manual <command>VACUUM</> should fix the problem, as suggested by the
528 hint; but note that the <command>VACUUM</> must be performed by a
529 superuser, else it will fail to process system catalogs and thus not
530 be able to advance the database's <structfield>datfrozenxid</>.)
531 If these warnings are
532 ignored, the system will shut down and refuse to execute any new
533 transactions once there are fewer than 1 million transactions left
534 until wraparound:
536 <programlisting>
537 ERROR: database is not accepting commands to avoid wraparound data loss in database "mydb"
538 HINT: Stop the postmaster and use a standalone backend to VACUUM in "mydb".
539 </programlisting>
541 The 1-million-transaction safety margin exists to let the
542 administrator recover without data loss, by manually executing the
543 required <command>VACUUM</> commands. However, since the system will not
544 execute commands once it has gone into the safety shutdown mode,
545 the only way to do this is to stop the server and use a single-user
546 backend to execute <command>VACUUM</>. The shutdown mode is not enforced
547 by a single-user backend. See the <xref linkend="app-postgres"> reference
548 page for details about using a single-user backend.
549 </para>
551 </sect2>
553 <sect2 id="autovacuum">
554 <title id="autovacuum-title">The Autovacuum Daemon</title>
556 <indexterm>
557 <primary>autovacuum</primary>
558 <secondary>general information</secondary>
559 </indexterm>
560 <para>
561 <productname>PostgreSQL</productname> has an optional but highly
562 recommended feature called <firstterm>autovacuum</firstterm>,
563 whose purpose is to automate the execution of
564 <command>VACUUM</command> and <command>ANALYZE </command> commands.
565 When enabled, autovacuum checks for
566 tables that have had a large number of inserted, updated or deleted
567 tuples. These checks use the statistics collection facility;
568 therefore, autovacuum cannot be used unless <xref
569 linkend="guc-track-counts"> is set to <literal>true</literal>.
570 In the default configuration, autovacuuming is enabled and the related
571 configuration parameters are appropriately set.
572 </para>
574 <para>
575 The <quote>autovacuum daemon</> actually consists of multiple processes.
576 There is a persistent daemon process, called the
577 <firstterm>autovacuum launcher</firstterm>, which is in charge of starting
578 <firstterm>autovacuum worker</firstterm> processes for all databases. The
579 launcher will distribute the work across time, attempting to start one
580 worker on each database every <xref linkend="guc-autovacuum-naptime">
581 seconds. One worker will be launched for each database, with a maximum
582 of <xref linkend="guc-autovacuum-max-workers"> processes running at the
583 same time. If there are more than
584 <xref linkend="guc-autovacuum-max-workers"> databases to be processed,
585 the next database will be processed as soon as the first worker finishes.
586 Each worker process will check each table within its database and
587 execute <command>VACUUM</> and/or <command>ANALYZE</> as needed.
588 </para>
590 <para>
591 The <xref linkend="guc-autovacuum-max-workers"> setting limits how many
592 workers may be running at any time. If several large tables all become
593 eligible for vacuuming in a short amount of time, all autovacuum workers
594 may become occupied with vacuuming those tables for a long period.
595 This would result
596 in other tables and databases not being vacuumed until a worker became
597 available. There is not a limit on how many workers might be in a
598 single database, but workers do try to avoid repeating work that has
599 already been done by other workers. Note that the number of running
600 workers does not count towards the <xref linkend="guc-max-connections"> nor
601 the <xref linkend="guc-superuser-reserved-connections"> limits.
602 </para>
604 <para>
605 Tables whose <structfield>relfrozenxid</> value is more than
606 <xref linkend="guc-autovacuum-freeze-max-age"> transactions old are always
607 vacuumed (this also applies to those tables whose freeze max age has
608 been modified via storage parameters; see below). Otherwise, if the
609 number of tuples obsoleted since the last
610 <command>VACUUM</command> exceeds the <quote>vacuum threshold</quote>, the
611 table is vacuumed. The vacuum threshold is defined as:
612 <programlisting>
613 vacuum threshold = vacuum base threshold + vacuum scale factor * number of tuples
614 </programlisting>
615 where the vacuum base threshold is
616 <xref linkend="guc-autovacuum-vacuum-threshold">,
617 the vacuum scale factor is
618 <xref linkend="guc-autovacuum-vacuum-scale-factor">,
619 and the number of tuples is
620 <structname>pg_class</structname>.<structfield>reltuples</structfield>.
621 The number of obsolete tuples is obtained from the statistics
622 collector; it is a semi-accurate count updated by each
623 <command>UPDATE</command> and <command>DELETE</command> operation. (It
624 is only semi-accurate because some information might be lost under heavy
625 load.) If the <structfield>relfrozenxid</> value of the table is more
626 than <varname>vacuum_freeze_table_age</> transactions old, the whole
627 table is scanned to freeze old tuples and advance
628 <structfield>relfrozenxid</>, otherwise only pages that have been modified
629 since the last vacuum are scanned.
630 </para>
632 <para>
633 For analyze, a similar condition is used: the threshold, defined as:
634 <programlisting>
635 analyze threshold = analyze base threshold + analyze scale factor * number of tuples
636 </programlisting>
637 is compared to the total number of tuples inserted or updated
638 since the last <command>ANALYZE</command>.
639 </para>
641 <para>
642 The default thresholds and scale factors are taken from
643 <filename>postgresql.conf</filename>, but it is possible to override them
644 on a table-by-table basis; see
645 <xref linkend="sql-createtable-storage-parameters"
646 endterm="sql-createtable-storage-parameters-title"> for more information.
647 If a setting
648 has been changed via storage parameters, that value is used; otherwise the
649 global settings are used. See <xref linkend="runtime-config-autovacuum"> for
650 more details on the global settings.
651 </para>
653 <para>
654 Besides the base threshold values and scale factors, there are six
655 more autovacuum parameters that can be set for each table via
656 storage parameters.
657 The first parameter, <literal>autovacuum_enabled</>,
658 can be set to <literal>false</literal> to instruct the autovacuum daemon
659 to skip that particular table entirely. In this case
660 autovacuum will only touch the table if it must do so
661 to prevent transaction ID wraparound.
662 Another two parameters,
663 <literal>autovacuum_vacuum_cost_delay</literal> and
664 <literal>autovacuum_vacuum_cost_limit</literal>, are used to set
665 table-specific values for the
666 <xref linkend="runtime-config-resource-vacuum-cost"
667 endterm="runtime-config-resource-vacuum-cost-title">
668 feature.
669 <literal>autovacuum_freeze_min_age</literal>,
670 <literal>autovacuum_freeze_max_age</literal> and
671 <literal>autovacuum_freeze_table_age</literal> are used to set
672 values for <xref linkend="guc-vacuum-freeze-min-age">,
673 <xref linkend="guc-autovacuum-freeze-max-age"> and
674 <xref linkend="guc-vacuum-freeze-table-age"> respectively.
675 </para>
677 <para>
678 When multiple workers are running, the cost limit is
679 <quote>balanced</quote> among all the running workers, so that the
680 total impact on the system is the same, regardless of the number
681 of workers actually running.
682 </para>
683 </sect2>
684 </sect1>
687 <sect1 id="routine-reindex">
688 <title>Routine Reindexing</title>
690 <indexterm zone="routine-reindex">
691 <primary>reindex</primary>
692 </indexterm>
694 <para>
695 In some situations it is worthwhile to rebuild indexes periodically
696 with the <xref linkend="sql-reindex" endterm="sql-reindex-title">
697 command.
698 </para>
700 <para>
701 In <productname>PostgreSQL</> releases before 7.4, periodic reindexing
702 was frequently necessary to avoid <quote>index bloat</>, due to lack of
703 internal space reclamation in B-tree indexes. Any situation in which the
704 range of index keys changed over time &mdash; for example, an index on
705 timestamps in a table where old entries are eventually deleted &mdash;
706 would result in bloat, because index pages for no-longer-needed portions
707 of the key range were not reclaimed for re-use. Over time, the index size
708 could become indefinitely much larger than the amount of useful data in it.
709 </para>
711 <para>
712 In <productname>PostgreSQL</> 7.4 and later, index pages that have become
713 completely empty are reclaimed for re-use. There is still a possibility
714 for inefficient use of space: if all but a few index keys on a page have
715 been deleted, the page remains allocated. So a usage pattern in which all
716 but a few keys in each range are eventually deleted will see poor use of
717 space. For such usage patterns, periodic reindexing is recommended.
718 </para>
720 <para>
721 The potential for bloat in non-B-tree indexes has not been well
722 characterized. It is a good idea to keep an eye on the index's physical
723 size when using any non-B-tree index type.
724 </para>
726 <para>
727 Also, for B-tree indexes a freshly-constructed index is somewhat faster to
728 access than one that has been updated many times, because logically
729 adjacent pages are usually also physically adjacent in a newly built index.
730 (This consideration does not currently apply to non-B-tree indexes.) It
731 might be worthwhile to reindex periodically just to improve access speed.
732 </para>
733 </sect1>
736 <sect1 id="logfile-maintenance">
737 <title>Log File Maintenance</title>
739 <indexterm zone="logfile-maintenance">
740 <primary>server log</primary>
741 <secondary>log file maintenance</secondary>
742 </indexterm>
744 <para>
745 It is a good idea to save the database server's log output
746 somewhere, rather than just routing it to <filename>/dev/null</>.
747 The log output is invaluable when it comes time to diagnose
748 problems. However, the log output tends to be voluminous
749 (especially at higher debug levels) and you won't want to save it
750 indefinitely. You need to <quote>rotate</> the log files so that
751 new log files are started and old ones removed after a reasonable
752 period of time.
753 </para>
755 <para>
756 If you simply direct the <systemitem>stderr</> of
757 <command>postgres</command> into a
758 file, you will have log output, but
759 the only way to truncate the log file is to stop and restart
760 the server. This might be OK if you are using
761 <productname>PostgreSQL</productname> in a development environment,
762 but few production servers would find this behavior acceptable.
763 </para>
765 <para>
766 A better approach is to send the server's
767 <systemitem>stderr</> output to some type of log rotation program.
768 There is a built-in log rotation program, which you can use by
769 setting the configuration parameter <literal>logging_collector</> to
770 <literal>true</> in <filename>postgresql.conf</>. The control
771 parameters for this program are described in <xref
772 linkend="runtime-config-logging-where">. You can also use this approach
773 to capture the log data in machine readable CSV format.
774 </para>
776 <para>
777 Alternatively, you might prefer to use an external log rotation
778 program, if you have one that you are already using with other
779 server software. For example, the <application>rotatelogs</application>
780 tool included in the <productname>Apache</productname> distribution
781 can be used with <productname>PostgreSQL</productname>. To do this,
782 just pipe the server's
783 <systemitem>stderr</> output to the desired program.
784 If you start the server with
785 <command>pg_ctl</>, then <systemitem>stderr</>
786 is already redirected to <systemitem>stdout</>, so you just need a
787 pipe command, for example:
789 <programlisting>
790 pg_ctl start | rotatelogs /var/log/pgsql_log 86400
791 </programlisting>
792 </para>
794 <para>
795 Another production-grade approach to managing log output is to
796 send it all to <application>syslog</> and let
797 <application>syslog</> deal with file rotation. To do this, set the
798 configuration parameter <literal>log_destination</> to <literal>syslog</>
799 (to log to <application>syslog</> only) in
800 <filename>postgresql.conf</>. Then you can send a <literal>SIGHUP</literal>
801 signal to the <application>syslog</> daemon whenever you want to force it
802 to start writing a new log file. If you want to automate log
803 rotation, the <application>logrotate</application> program can be
804 configured to work with log files from
805 <application>syslog</application>.
806 </para>
808 <para>
809 On many systems, however, <application>syslog</> is not very reliable,
810 particularly with large log messages; it might truncate or drop messages
811 just when you need them the most. Also, on <productname>Linux</>,
812 <application>syslog</> will sync each message to disk, yielding poor
813 performance. (You can use a <literal>-</> at the start of the file name
814 in the <application>syslog</> configuration file to disable syncing.)
815 </para>
817 <para>
818 Note that all the solutions described above take care of starting new
819 log files at configurable intervals, but they do not handle deletion
820 of old, no-longer-interesting log files. You will probably want to set
821 up a batch job to periodically delete old log files. Another possibility
822 is to configure the rotation program so that old log files are overwritten
823 cyclically.
824 </para>
825 </sect1>
826 </chapter>