1 2 3 4 5 6 7 8 9 10 11 12 13 14 15 16 17 18 19 20 21 22 23 24 25 26 27 28 29 30 31 32 33 34 35 36 37 38 39 40 41 42 43 44 45 46 47 48 49 50 51 52 53 54 55 56 57 58 59 60 61 62 63 64 65 66 67 68 69 70 71 72 73 74 75 76 77 78 79 80 81 82 83 84 85 86 87 88 89 90 91 92 93 94 95 96 97 98 99 100 101 102 103 104 105 106 107 108 109 110 111 112 113 114 115 116 117 118 119 120 121 122 123 124 125 126 127 128 129 130 131 132 133 134 135 136 137 138 139 140 141 142 143 144 145 146 147 148 149 150 151 152 153 154 155 156 157 158 159 160 161 162 163 164 165 166 167 168 169 170 171 172 173 174 175 176 177 178 179 180 181 182 183 184 185 186 187 188 189 190 191 192 193 194 195 196 197 198 199 200 201 202 203 204 205 206 207 208 209 210 211 212 213 214 215 216 217 218 219 220 221 222 223 224 225 226 227 228 229 230 231 232 233 234 235 236 237 238 239 240 241 242 243 244 245 246 247 248 249 250 251 252 253 254 255 256 257 258 259 260 261 262 263 264 265 266 267 268 269 270 271 272 273 274 275 276 277 278 279 280 281 282 283 284 285 286 287 288 289 290 291 292 293 294 295 296 297 298 299 300 301 302 303 304 305 306 307 308 309 310 311 312 313 314 315 316 317 318 319 320 321 322 323 324 325 326 327 328 329 330 331 332 333 334 335 336 337 338 339 340 341 342 343 344 345 346 347 348 349 350 351 352 353 354 355 356 357 358 359 360 361 362 363 364 365 366 367 368 369 370 371 372 373 374 375 376 377 378 379 380 381 382 383 384 385 386 387 388 389 390 391 392 393 394 395 396 397 398 399 400 401 402 403 404 405 406 407 408 409 410 411 412 413 414 415 416 417 418 419 420 421 422 423 424 425 426 427 428 429 430 431 432 433 434 435 436 437 438 439 440 441 442 443 444 445 446 447 448 449 450 451 452 453 454 455 456 457 458 459 460 461 462 463 464 465 466 467 468 469 470 471 472 473 474 475 476 477 478 479 480 481 482 483 484 485 486 487 488
|
<html>
<head>
<meta http-equiv="Content-Type" content="text/html; charset=ISO-8859-1">
<title>Chapter22.Routine Database Maintenance Tasks</title>
<link rel="stylesheet" href="stylesheet.css" type="text/css">
<link rev="made" href="pgsql-docs@postgresql.org">
<meta name="generator" content="DocBook XSL Stylesheets V1.70.0">
<link rel="start" href="index.html" title="PostgreSQL 8.1.4 Documentation">
<link rel="up" href="admin.html" title="PartIII.Server Administration">
<link rel="prev" href="multibyte.html" title="21.2.Character Set Support">
<link rel="next" href="routine-reindex.html" title="22.2.Routine Reindexing">
<link rel="copyright" href="ln-legalnotice.html" title="Legal Notice">
</head>
<body bgcolor="white" text="black" link="#0000FF" vlink="#840084" alink="#0000FF"><div class="chapter" lang="en" id="maintenance">
<div class="titlepage"><div><div><h2 class="title">
<a name="maintenance"></a>Chapter22.Routine Database Maintenance Tasks</h2></div></div></div>
<div class="toc">
<p><b>Table of Contents</b></p>
<dl>
<dt><span class="sect1"><a href="maintenance.html#routine-vacuuming">22.1. Routine Vacuuming</a></span></dt>
<dd><dl>
<dt><span class="sect2"><a href="maintenance.html#vacuum-for-space-recovery">22.1.1. Recovering disk space</a></span></dt>
<dt><span class="sect2"><a href="maintenance.html#vacuum-for-statistics">22.1.2. Updating planner statistics</a></span></dt>
<dt><span class="sect2"><a href="maintenance.html#vacuum-for-wraparound">22.1.3. Preventing transaction ID wraparound failures</a></span></dt>
<dt><span class="sect2"><a href="maintenance.html#autovacuum">22.1.4. The auto-vacuum daemon</a></span></dt>
</dl></dd>
<dt><span class="sect1"><a href="routine-reindex.html">22.2. Routine Reindexing</a></span></dt>
<dt><span class="sect1"><a href="logfile-maintenance.html">22.3. Log File Maintenance</a></span></dt>
</dl>
</div>
<a name="id666256"></a><p> There are a few routine maintenance chores that must be performed on
a regular basis to keep a <span class="productname">PostgreSQL</span>
server running smoothly. The tasks discussed here are repetitive
in nature and can easily be automated using standard Unix tools such
as <span class="application">cron</span> scripts. But it is the database
administrator's responsibility to set up appropriate scripts, and to
check that they execute successfully.
</p>
<p> 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
<span class="productname">PostgreSQL</span> are discussed at length in
<a href="backup.html" title="Chapter23.Backup and Restore">Chapter23, <i>Backup and Restore</i></a>.
</p>
<p> The other main category of maintenance task is periodic “<span class="quote">vacuuming</span>”
of the database. This activity is discussed in
<a href="maintenance.html#routine-vacuuming" title="22.1.Routine Vacuuming">Section22.1, “Routine Vacuuming”</a>.
</p>
<p> Something else that might need periodic attention is log file management.
This is discussed in <a href="logfile-maintenance.html" title="22.3.Log File Maintenance">Section22.3, “Log File Maintenance”</a>.
</p>
<p> <span class="productname">PostgreSQL</span> 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.
</p>
<div class="sect1" lang="en">
<div class="titlepage"><div><div><h2 class="title" style="clear: both">
<a name="routine-vacuuming"></a>22.1.Routine Vacuuming</h2></div></div></div>
<a name="id666360"></a><p> <span class="productname">PostgreSQL</span>'s <code class="command">VACUUM</code> command
must be run on a regular basis for several reasons:
</p>
<div class="orderedlist"><ol type="1">
<li>To recover disk space occupied by updated or deleted
rows.</li>
<li>To update data statistics used by the
<span class="productname">PostgreSQL</span> query planner.</li>
<li>To protect against loss of very old data due to
<em class="firstterm">transaction ID wraparound</em>.</li>
</ol></div>
<p>
The frequency and scope of the <code class="command">VACUUM</code> 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 <a href="sql-vacuum.html">VACUUM</a> reference page.
</p>
<p> Beginning in <span class="productname">PostgreSQL</span> 7.2, the standard form
of <code class="command">VACUUM</code> can run in parallel with normal database operations
(selects, inserts, updates, deletes, but not changes to table definitions).
Routine vacuuming is therefore not nearly as intrusive as it was in prior
releases, and it is not as critical to try to schedule it at low-usage
times of day.
</p>
<p> Beginning in <span class="productname">PostgreSQL</span> 8.0, there are
configuration parameters that can be adjusted to further reduce the
performance impact of background vacuuming. See
<a href="runtime-config-resource.html#runtime-config-resource-vacuum-cost" title="17.4.4. Cost-Based Vacuum Delay
">Section17.4.4, “ Cost-Based Vacuum Delay
”</a>.
</p>
<p> An automated mechanism for performing the necessary <code class="command">VACUUM</code>
operations has been added in <span class="productname">PostgreSQL</span> 8.1.
See <a href="maintenance.html#autovacuum" title="22.1.4.The auto-vacuum daemon">Section22.1.4, “The auto-vacuum daemon”</a>.
</p>
<div class="sect2" lang="en">
<div class="titlepage"><div><div><h3 class="title">
<a name="vacuum-for-space-recovery"></a>22.1.1.Recovering disk space</h3></div></div></div>
<a name="id666519"></a><p> In normal <span class="productname">PostgreSQL</span> operation, an
<code class="command">UPDATE</code> or <code class="command">DELETE</code> 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 <a href="mvcc.html" title="Chapter12.Concurrency Control">Chapter12, <i>Concurrency Control</i></a>): 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 <code class="command">VACUUM</code>.
</p>
<p> Clearly, a table that receives frequent updates or deletes will need
to be vacuumed more often than tables that are seldom updated. It
may be useful to set up periodic <span class="application">cron</span> tasks that
<code class="command">VACUUM</code> 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.
</p>
<p> There are two variants of the <code class="command">VACUUM</code>
command. The first form, known as “<span class="quote">lazy vacuum</span>” or
just <code class="command">VACUUM</code>, marks expired data in tables and
indexes for future reuse; it does <span class="emphasis"><em>not</em></span> attempt
to reclaim the space used by this expired data unless the space is
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 <code class="command">VACUUM</code> can be
run concurrently with normal database operations.
</p>
<p> The second form is the <code class="command">VACUUM FULL</code>
command. This uses a more aggressive algorithm for reclaiming the
space consumed by expired row versions. Any space that is freed by
<code class="command">VACUUM FULL</code> is immediately returned to the
operating system. Unfortunately, this variant of the
<code class="command">VACUUM</code> command acquires an exclusive lock on
each table while <code class="command">VACUUM FULL</code> is processing
it. Therefore, frequently using <code class="command">VACUUM FULL</code> can
have an extremely negative effect on the performance of concurrent
database queries.
</p>
<p> The standard form of <code class="command">VACUUM</code> 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
<code class="command">VACUUM FULL</code> [mdash ] but what's the point of releasing disk
space that will only have to be allocated again soon? Moderately
frequent standard <code class="command">VACUUM</code> runs are a better approach
than infrequent <code class="command">VACUUM FULL</code> runs for maintaining
heavily-updated tables.
</p>
<p> Recommended practice for most sites is to schedule a database-wide
<code class="command">VACUUM</code> once a day at a low-usage time of day,
supplemented by more frequent vacuuming of heavily-updated tables
if necessary. (Some installations with an extremely high
rate of data modification <code class="command">VACUUM</code> busy tables as
often as once every few minutes.) If you have multiple databases
in a cluster, don't forget to <code class="command">VACUUM</code> each one;
the program <a href="app-vacuumdb.html"><span class="application">vacuumdb</span></a>
may be helpful.
</p>
<p> <code class="command">VACUUM FULL</code> 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
<code class="command">VACUUM FULL</code>'s more aggressive approach. Use plain
<code class="command">VACUUM</code>, not <code class="command">VACUUM FULL</code>, for routine
vacuuming for space recovery.
</p>
<p> If you have a table whose contents are deleted on a periodic
basis, consider doing it with <code class="command">TRUNCATE</code> rather
than using <code class="command">DELETE</code> followed by
<code class="command">VACUUM</code>. <code class="command">TRUNCATE</code> removes the
entire content of the table immediately, without requiring a
subsequent <code class="command">VACUUM</code> or <code class="command">VACUUM
FULL</code> to reclaim the now-unused disk space.
</p>
</div>
<div class="sect2" lang="en">
<div class="titlepage"><div><div><h3 class="title">
<a name="vacuum-for-statistics"></a>22.1.2.Updating planner statistics</h3></div></div></div>
<a name="id666850"></a><a name="id666865"></a><p> The <span class="productname">PostgreSQL</span> 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 <code class="command">ANALYZE</code> command, which can be invoked by itself or
as an optional step in <code class="command">VACUUM</code>. It is important to have
reasonably accurate statistics, otherwise poor choices of plans may
degrade database performance.
</p>
<p> 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 may 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 <code class="type">timestamp</code> 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 may receive changes just
as often, but the statistical distribution of its values probably
changes relatively slowly.
</p>
<p> It is possible to run <code class="command">ANALYZE</code> 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, the usefulness of this feature is doubtful.
Beginning in <span class="productname">PostgreSQL</span> 7.2,
<code class="command">ANALYZE</code> is a fairly fast operation even on large tables,
because it uses a statistical random sampling of the rows of a table
rather than reading every single row. So it's probably much simpler
to just run it over the whole database every so often.
</p>
<div class="tip" style="margin-left: 0.5in; margin-right: 0.5in;">
<h3 class="title">Tip</h3>
<p> Although per-column tweaking of <code class="command">ANALYZE</code> frequency may not be
very productive, you may well find it worthwhile to do per-column
adjustment of the level of detail of the statistics collected by
<code class="command">ANALYZE</code>. Columns that are heavily used in <code class="literal">WHERE</code> clauses
and have highly irregular data distributions may require a finer-grain
data histogram than other columns. See <code class="command">ALTER TABLE SET
STATISTICS</code>.
</p>
</div>
<p> Recommended practice for most sites is to schedule a database-wide
<code class="command">ANALYZE</code> once a day at a low-usage time of day; this can
usefully be combined with a nightly <code class="command">VACUUM</code>. However,
sites with relatively slowly changing table statistics may find that
this is overkill, and that less-frequent <code class="command">ANALYZE</code> runs
are sufficient.
</p>
</div>
<div class="sect2" lang="en">
<div class="titlepage"><div><div><h3 class="title">
<a name="vacuum-for-wraparound"></a>22.1.3.Preventing transaction ID wraparound failures</h3></div></div></div>
<a name="id667029"></a><p> <span class="productname">PostgreSQL</span>'s MVCC transaction semantics
depend on being able to compare transaction ID (<acronym class="acronym">XID</acronym>)
numbers: a row version with an insertion XID greater than the current
transaction's XID is “<span class="quote">in the future</span>” 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 <em class="firstterm">transaction ID
wraparound</em>: 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
means their outputs become invisible. In short, catastrophic data loss.
(Actually the data is still there, but that's cold comfort if you can't
get at it.)
</p>
<p> Prior to <span class="productname">PostgreSQL</span> 7.2, the only defense
against XID wraparound was to re-<code class="command">initdb</code> at least every 4
billion transactions. This of course was not very satisfactory for
high-traffic sites, so a better solution has been devised. The new
approach allows a server to remain up indefinitely, without
<code class="command">initdb</code> or any sort of restart. The price is this
maintenance requirement: <span class="emphasis"><em>every table in the database must
be vacuumed at least once every billion transactions</em></span>.
</p>
<p> In practice this isn't an onerous requirement, but since the
consequences of failing to meet it can be complete data loss (not
just wasted disk space or slow performance), some special provisions
have been made to help database administrators avoid disaster.
For each database in the cluster, <span class="productname">PostgreSQL</span>
keeps track of the time of the last database-wide <code class="command">VACUUM</code>.
When any database approaches the billion-transaction danger level,
the system begins to emit warning messages. If nothing is done, it
will eventually shut down normal operations until appropriate
manual maintenance is done. The remainder of this
section gives the details.
</p>
<p> The new approach to XID comparison distinguishes two special XIDs,
numbers 1 and 2 (<code class="literal">BootstrapXID</code> and
<code class="literal">FrozenXID</code>). These two XIDs are always considered older
than every normal XID. Normal XIDs (those greater than 2) are
compared using modulo-2<sup>31</sup> arithmetic. This means
that for every normal XID, there are two billion XIDs that are
“<span class="quote">older</span>” and two billion that are “<span class="quote">newer</span>”; 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 “<span class="quote">in the past</span>” 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
<code class="literal">FrozenXID</code> sometime before they reach the
two-billion-transactions-old mark. Once they are assigned this
special XID, they will appear to be “<span class="quote">in the past</span>” 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 XID is handled by <code class="command">VACUUM</code>.
</p>
<p> <code class="command">VACUUM</code>'s normal policy is to reassign <code class="literal">FrozenXID</code>
to any row version with a normal XID more than one billion transactions in the
past. This policy preserves the original insertion XID until it is not
likely to be of interest anymore. (In fact, most row versions will probably
live and die without ever being “<span class="quote">frozen</span>”.) With this policy,
the maximum safe interval between <code class="command">VACUUM</code> runs on any table
is exactly one billion transactions: if you wait longer, it's possible
that a row version that was not quite old enough to be reassigned last time
is now more than two billion transactions old and has wrapped around
into the future [mdash ] i.e., is lost to you. (Of course, it'll reappear
after another two billion transactions, but that's no help.)
</p>
<p> Since periodic <code class="command">VACUUM</code> runs are needed anyway for the reasons
described earlier, it's unlikely that any table would not be vacuumed
for as long as a billion transactions. But to help administrators ensure
this constraint is met, <code class="command">VACUUM</code> stores transaction ID
statistics in the system table <code class="literal">pg_database</code>. In particular,
the <code class="literal">datfrozenxid</code> column of a database's
<code class="literal">pg_database</code> row is updated at the completion of any
database-wide <code class="command">VACUUM</code> operation (i.e.,
<code class="command">VACUUM</code> that does not
name a specific table). The value stored in this field is the freeze
cutoff XID that was used by that <code class="command">VACUUM</code> command. All normal
XIDs older than this cutoff XID are guaranteed to have been replaced by
<code class="literal">FrozenXID</code> within that database. A convenient way to
examine this information is to execute the query
</p>
<pre class="programlisting">SELECT datname, age(datfrozenxid) FROM pg_database;</pre>
<p>
The <code class="literal">age</code> column measures the number of transactions from the
cutoff XID to the current transaction's XID.
</p>
<p> With the standard freezing policy, the <code class="literal">age</code> column will start
at one billion for a freshly-vacuumed database. When the <code class="literal">age</code>
approaches two billion, the database must be vacuumed again to avoid
risk of wraparound failures. Recommended practice is to <code class="command">VACUUM</code> each
database at least once every half-a-billion (500 million) transactions,
so as to provide plenty of safety margin. To help meet this rule,
each database-wide <code class="command">VACUUM</code> automatically delivers a warning
if there are any <code class="literal">pg_database</code> entries showing an
<code class="literal">age</code> of more than 1.5 billion transactions, for example:
</p>
<pre class="programlisting">play=# VACUUM;
WARNING: database "mydb" must be vacuumed within 177009986 transactions
HINT: To avoid a database shutdown, execute a full-database VACUUM in "mydb".
VACUUM</pre>
<p>
</p>
<p> If the warnings emitted by <code class="command">VACUUM</code> go ignored, then
<span class="productname">PostgreSQL</span> will begin to emit a warning
like the above on every transaction start once there are fewer than 10
million transactions left until wraparound. If those warnings also 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:
</p>
<pre class="programlisting">play=# select 2+2;
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".</pre>
<p>
The 1-million-transaction safety margin exists to let the
administrator recover without data loss, by manually executing the
required <code class="command">VACUUM</code> 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 postmaster and use a standalone
backend to execute <code class="command">VACUUM</code>. The shutdown mode is not enforced
by a standalone backend. See the <a href="app-postgres.html" title="postgres"><span class="refentrytitle"><a name="app-postgres-title"></a><span class="application">postgres</span></span></a> reference
page for details about using a standalone backend.
</p>
<p> <code class="command">VACUUM</code> with the <code class="command">FREEZE</code> option uses a more
aggressive freezing policy: row versions are frozen if they are old enough
to be considered good by all open transactions. In particular, if a
<code class="command">VACUUM FREEZE</code> is performed in an otherwise-idle
database, it is guaranteed that <span class="emphasis"><em>all</em></span> row versions in that
database will be frozen. Hence, as long as the database is not
modified in any way, it will not need subsequent vacuuming to avoid
transaction ID wraparound problems. This technique is used by
<code class="command">initdb</code> to prepare the <code class="literal">template0</code> database.
It should also be used to prepare any user-created databases that
are to be marked <code class="literal">datallowconn</code> = <code class="literal">false</code> in
<code class="literal">pg_database</code>, since there isn't any convenient way to
<code class="command">VACUUM</code> a database that you can't connect to.
</p>
<div class="warning" style="margin-left: 0.5in; margin-right: 0.5in;">
<h3 class="title">Warning</h3>
<p> A database that is marked <code class="literal">datallowconn</code> = <code class="literal">false</code>
in <code class="literal">pg_database</code> is assumed to be properly frozen; the
automatic warnings and wraparound protection shutdown do not take
such databases into account. Therefore it's up to you to ensure
you've correctly frozen a database before you mark it with
<code class="literal">datallowconn</code> = <code class="literal">false</code>.
</p>
</div>
</div>
<div class="sect2" lang="en">
<div class="titlepage"><div><div><h3 class="title">
<a name="autovacuum"></a>22.1.4.The auto-vacuum daemon</h3></div></div></div>
<a name="id667584"></a><p> Beginning in <span class="productname">PostgreSQL </span> 8.1, there is a
separate optional server process called the <em class="firstterm">autovacuum
daemon</em>, whose purpose is to automate the execution of
<code class="command">VACUUM</code> and <code class="command">ANALYZE </code> commands.
When enabled, the autovacuum daemon runs periodically and checks for
tables that have had a large number of inserted, updated or deleted
tuples. These checks use the row-level statistics collection facility;
therefore, the autovacuum daemon cannot be used unless <a href="runtime-config-statistics.html#guc-stats-start-collector">stats_start_collector</a> and <a href="runtime-config-statistics.html#guc-stats-row-level">stats_row_level</a> are set to <code class="literal">true</code>. Also,
it's important to allow a slot for the autovacuum process when choosing
the value of <a href="runtime-config-connection.html#guc-superuser-reserved-connections">superuser_reserved_connections</a>.
</p>
<p> The autovacuum daemon, when enabled, runs every <a href="runtime-config-autovacuum.html#guc-autovacuum-naptime">autovacuum_naptime</a> seconds and determines which database
to process. Any database which is close to transaction ID wraparound
is immediately processed. In this case, autovacuum issues a
database-wide <code class="command">VACUUM</code> call, or <code class="command">VACUUM
FREEZE</code> if it's a template database, and then terminates. If
no database fulfills this criterion, the one that was least recently
processed by autovacuum is chosen. In this case each table in
the selected database is checked, and individual <code class="command">VACUUM</code>
or <code class="command">ANALYZE</code> commands are issued as needed.
</p>
<p> For each table, two conditions are used to determine which operation(s)
to apply. If the number of obsolete tuples since the last
<code class="command">VACUUM</code> exceeds the “<span class="quote">vacuum threshold</span>”, the
table is vacuumed. The vacuum threshold is defined as:
</p>
<pre class="programlisting">vacuum threshold = vacuum base threshold + vacuum scale factor * number of tuples</pre>
<p>
where the vacuum base threshold is
<a href="runtime-config-autovacuum.html#guc-autovacuum-vacuum-threshold">autovacuum_vacuum_threshold</a>,
the vacuum scale factor is
<a href="runtime-config-autovacuum.html#guc-autovacuum-vacuum-scale-factor">autovacuum_vacuum_scale_factor</a>,
and the number of tuples is
<code class="structname">pg_class</code>.<code class="structfield">reltuples</code>.
The number of obsolete tuples is obtained from the statistics
collector; it is a semi-accurate count updated by each
<code class="command">UPDATE</code> and <code class="command">DELETE</code> operation. (It
is only semi-accurate because some information may be lost under heavy
load.) For analyze, a similar condition is used: the threshold, defined as
</p>
<pre class="programlisting">analyze threshold = analyze base threshold + analyze scale factor * number of tuples</pre>
<p>
is compared to the total number of tuples inserted, updated, or deleted
since the last <code class="command">ANALYZE</code>.
</p>
<p> The default thresholds and scale factors are taken from
<code class="filename">postgresql.conf</code>, but it is possible to override them
on a table-by-table basis by making entries in the system catalog
<a href="catalog-pg-autovacuum.html" title="42.10.pg_autovacuum"><code class="structname">pg_autovacuum</code></a>.
If a <code class="structname">pg_autovacuum</code> row exists for a particular
table, the settings it specifies are applied; otherwise the global
settings are used. See <a href="runtime-config-autovacuum.html" title="17.9.Automatic Vacuuming">Section17.9, “Automatic Vacuuming”</a> for
more details on the global settings.
</p>
<p> Besides the base threshold values and scale factors, there are three
more parameters that can be set for each table in
<code class="structname">pg_autovacuum</code>.
The first, <code class="structname">pg_autovacuum</code>.<code class="structfield">enabled</code>,
can be set to <code class="literal">false</code> to instruct the autovacuum daemon
to skip that particular table entirely. In this case
autovacuum will only touch the table when it vacuums the entire database
to prevent transaction ID wraparound.
The other two parameters, the vacuum cost delay
(<code class="structname">pg_autovacuum</code>.<code class="structfield">vac_cost_delay</code>)
and the vacuum cost limit
(<code class="structname">pg_autovacuum</code>.<code class="structfield">vac_cost_limit</code>),
are used to set table-specific values for the
<a href="runtime-config-resource.html#runtime-config-resource-vacuum-cost"> Cost-Based Vacuum Delay
</a>
feature.
</p>
<p> If any of the values in <code class="structname">pg_autovacuum</code>
are set to a negative number, or if a row is not present at all in
<code class="structname">pg_autovacuum</code> for any particular table, the
corresponding values from <code class="filename">postgresql.conf</code> are used.
</p>
<p> There is not currently any support for making
<code class="structname">pg_autovacuum</code> entries, except by doing
manual <code class="command">INSERT</code>s into the catalog. This feature will be
improved in future releases, and it is likely that the catalog
definition will change.
</p>
<div class="caution" style="margin-left: 0.5in; margin-right: 0.5in;">
<h3 class="title">Caution</h3>
<p> The contents of the <code class="structname">pg_autovacuum</code> system
catalog are currently not saved in database dumps created by
the tools <code class="command">pg_dump</code> and <code class="command">pg_dumpall</code>.
If you want to preserve them across a dump/reload cycle, make sure you
dump the catalog manually.
</p>
</div>
</div>
</div>
</div></body>
</html>
|