summaryrefslogtreecommitdiffstats
path: root/doc/src/sgml/man7/VACUUM.7
blob: a34681411e593341f030cc3adf03de2021cd3df1 (plain)
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
'\" t
.\"     Title: VACUUM
.\"    Author: The PostgreSQL Global Development Group
.\" Generator: DocBook XSL Stylesheets vsnapshot <http://docbook.sf.net/>
.\"      Date: 2024
.\"    Manual: PostgreSQL 16.2 Documentation
.\"    Source: PostgreSQL 16.2
.\"  Language: English
.\"
.TH "VACUUM" "7" "2024" "PostgreSQL 16.2" "PostgreSQL 16.2 Documentation"
.\" -----------------------------------------------------------------
.\" * Define some portability stuff
.\" -----------------------------------------------------------------
.\" ~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~
.\" http://bugs.debian.org/507673
.\" http://lists.gnu.org/archive/html/groff/2009-02/msg00013.html
.\" ~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~
.ie \n(.g .ds Aq \(aq
.el       .ds Aq '
.\" -----------------------------------------------------------------
.\" * set default formatting
.\" -----------------------------------------------------------------
.\" disable hyphenation
.nh
.\" disable justification (adjust text to left margin only)
.ad l
.\" -----------------------------------------------------------------
.\" * MAIN CONTENT STARTS HERE *
.\" -----------------------------------------------------------------
.SH "NAME"
VACUUM \- garbage\-collect and optionally analyze a database
.SH "SYNOPSIS"
.sp
.nf
VACUUM [ ( \fIoption\fR [, \&.\&.\&.] ) ] [ \fItable_and_columns\fR [, \&.\&.\&.] ]
VACUUM [ FULL ] [ FREEZE ] [ VERBOSE ] [ ANALYZE ] [ \fItable_and_columns\fR [, \&.\&.\&.] ]

where \fIoption\fR can be one of:

    FULL [ \fIboolean\fR ]
    FREEZE [ \fIboolean\fR ]
    VERBOSE [ \fIboolean\fR ]
    ANALYZE [ \fIboolean\fR ]
    DISABLE_PAGE_SKIPPING [ \fIboolean\fR ]
    SKIP_LOCKED [ \fIboolean\fR ]
    INDEX_CLEANUP { AUTO | ON | OFF }
    PROCESS_MAIN [ \fIboolean\fR ]
    PROCESS_TOAST [ \fIboolean\fR ]
    TRUNCATE [ \fIboolean\fR ]
    PARALLEL \fIinteger\fR
    SKIP_DATABASE_STATS [ \fIboolean\fR ]
    ONLY_DATABASE_STATS [ \fIboolean\fR ]
    BUFFER_USAGE_LIMIT \fIsize\fR

and \fItable_and_columns\fR is:

    \fItable_name\fR [ ( \fIcolumn_name\fR [, \&.\&.\&.] ) ]
.fi
.SH "DESCRIPTION"
.PP
\fBVACUUM\fR
reclaims storage occupied by dead tuples\&. In normal
PostgreSQL
operation, tuples that are deleted or obsoleted by an update are not physically removed from their table; they remain present until a
\fBVACUUM\fR
is done\&. Therefore it\*(Aqs necessary to do
\fBVACUUM\fR
periodically, especially on frequently\-updated tables\&.
.PP
Without a
\fItable_and_columns\fR
list,
\fBVACUUM\fR
processes every table and materialized view in the current database that the current user has permission to vacuum\&. With a list,
\fBVACUUM\fR
processes only those table(s)\&.
.PP
\fBVACUUM ANALYZE\fR
performs a
\fBVACUUM\fR
and then an
\fBANALYZE\fR
for each selected table\&. This is a handy combination form for routine maintenance scripts\&. See
\fBANALYZE\fR(7)
for more details about its processing\&.
.PP
Plain
\fBVACUUM\fR
(without
FULL) simply reclaims space and makes it available for re\-use\&. This form of the command can operate in parallel with normal reading and writing of the table, as an exclusive lock is not obtained\&. However, extra space is not returned to the operating system (in most cases); it\*(Aqs just kept available for re\-use within the same table\&. It also allows us to leverage multiple CPUs in order to process indexes\&. This feature is known as
parallel vacuum\&. To disable this feature, one can use
PARALLEL
option and specify parallel workers as zero\&.
\fBVACUUM FULL\fR
rewrites the entire contents of the table into a new disk file with no extra space, allowing unused space to be returned to the operating system\&. This form is much slower and requires an
ACCESS EXCLUSIVE
lock on each table while it is being processed\&.
.PP
When the option list is surrounded by parentheses, the options can be written in any order\&. Without parentheses, options must be specified in exactly the order shown above\&. The parenthesized syntax was added in
PostgreSQL
9\&.0; the unparenthesized syntax is deprecated\&.
.SH "PARAMETERS"
.PP
FULL
.RS 4
Selects
\(lqfull\(rq
vacuum, which can reclaim more space, but takes much longer and exclusively locks the table\&. This method also requires extra disk space, since it writes a new copy of the table and doesn\*(Aqt release the old copy until the operation is complete\&. Usually this should only be used when a significant amount of space needs to be reclaimed from within the table\&.
.RE
.PP
FREEZE
.RS 4
Selects aggressive
\(lqfreezing\(rq
of tuples\&. Specifying
FREEZE
is equivalent to performing
\fBVACUUM\fR
with the
vacuum_freeze_min_age
and
vacuum_freeze_table_age
parameters set to zero\&. Aggressive freezing is always performed when the table is rewritten, so this option is redundant when
FULL
is specified\&.
.RE
.PP
VERBOSE
.RS 4
Prints a detailed vacuum activity report for each table\&.
.RE
.PP
ANALYZE
.RS 4
Updates statistics used by the planner to determine the most efficient way to execute a query\&.
.RE
.PP
DISABLE_PAGE_SKIPPING
.RS 4
Normally,
\fBVACUUM\fR
will skip pages based on the
visibility map\&. Pages where all tuples are known to be frozen can always be skipped, and those where all tuples are known to be visible to all transactions may be skipped except when performing an aggressive vacuum\&. Furthermore, except when performing an aggressive vacuum, some pages may be skipped in order to avoid waiting for other sessions to finish using them\&. This option disables all page\-skipping behavior, and is intended to be used only when the contents of the visibility map are suspect, which should happen only if there is a hardware or software issue causing database corruption\&.
.RE
.PP
SKIP_LOCKED
.RS 4
Specifies that
\fBVACUUM\fR
should not wait for any conflicting locks to be released when beginning work on a relation: if a relation cannot be locked immediately without waiting, the relation is skipped\&. Note that even with this option,
\fBVACUUM\fR
may still block when opening the relation\*(Aqs indexes\&. Additionally,
\fBVACUUM ANALYZE\fR
may still block when acquiring sample rows from partitions, table inheritance children, and some types of foreign tables\&. Also, while
\fBVACUUM\fR
ordinarily processes all partitions of specified partitioned tables, this option will cause
\fBVACUUM\fR
to skip all partitions if there is a conflicting lock on the partitioned table\&.
.RE
.PP
INDEX_CLEANUP
.RS 4
Normally,
\fBVACUUM\fR
will skip index vacuuming when there are very few dead tuples in the table\&. The cost of processing all of the table\*(Aqs indexes is expected to greatly exceed the benefit of removing dead index tuples when this happens\&. This option can be used to force
\fBVACUUM\fR
to process indexes when there are more than zero dead tuples\&. The default is
AUTO, which allows
\fBVACUUM\fR
to skip index vacuuming when appropriate\&. If
INDEX_CLEANUP
is set to
ON,
\fBVACUUM\fR
will conservatively remove all dead tuples from indexes\&. This may be useful for backwards compatibility with earlier releases of
PostgreSQL
where this was the standard behavior\&.
.sp
INDEX_CLEANUP
can also be set to
OFF
to force
\fBVACUUM\fR
to
\fIalways\fR
skip index vacuuming, even when there are many dead tuples in the table\&. This may be useful when it is necessary to make
\fBVACUUM\fR
run as quickly as possible to avoid imminent transaction ID wraparound (see
Section\ \&25.1.5)\&. However, the wraparound failsafe mechanism controlled by
vacuum_failsafe_age
will generally trigger automatically to avoid transaction ID wraparound failure, and should be preferred\&. If index cleanup is not performed regularly, performance may suffer, because as the table is modified indexes will accumulate dead tuples and the table itself will accumulate dead line pointers that cannot be removed until index cleanup is completed\&.
.sp
This option has no effect for tables that have no index and is ignored if the
FULL
option is used\&. It also has no effect on the transaction ID wraparound failsafe mechanism\&. When triggered it will skip index vacuuming, even when
INDEX_CLEANUP
is set to
ON\&.
.RE
.PP
PROCESS_MAIN
.RS 4
Specifies that
\fBVACUUM\fR
should attempt to process the main relation\&. This is usually the desired behavior and is the default\&. Setting this option to false may be useful when it is only necessary to vacuum a relation\*(Aqs corresponding
TOAST
table\&.
.RE
.PP
PROCESS_TOAST
.RS 4
Specifies that
\fBVACUUM\fR
should attempt to process the corresponding
TOAST
table for each relation, if one exists\&. This is usually the desired behavior and is the default\&. Setting this option to false may be useful when it is only necessary to vacuum the main relation\&. This option is required when the
FULL
option is used\&.
.RE
.PP
TRUNCATE
.RS 4
Specifies that
\fBVACUUM\fR
should attempt to truncate off any empty pages at the end of the table and allow the disk space for the truncated pages to be returned to the operating system\&. This is normally the desired behavior and is the default unless the
vacuum_truncate
option has been set to false for the table to be vacuumed\&. Setting this option to false may be useful to avoid
ACCESS EXCLUSIVE
lock on the table that the truncation requires\&. This option is ignored if the
FULL
option is used\&.
.RE
.PP
PARALLEL
.RS 4
Perform index vacuum and index cleanup phases of
\fBVACUUM\fR
in parallel using
\fIinteger\fR
background workers (for the details of each vacuum phase, please refer to
Table\ \&28.45)\&. The number of workers used to perform the operation is equal to the number of indexes on the relation that support parallel vacuum which is limited by the number of workers specified with
PARALLEL
option if any which is further limited by
max_parallel_maintenance_workers\&. An index can participate in parallel vacuum if and only if the size of the index is more than
min_parallel_index_scan_size\&. Please note that it is not guaranteed that the number of parallel workers specified in
\fIinteger\fR
will be used during execution\&. It is possible for a vacuum to run with fewer workers than specified, or even with no workers at all\&. Only one worker can be used per index\&. So parallel workers are launched only when there are at least
2
indexes in the table\&. Workers for vacuum are launched before the start of each phase and exit at the end of the phase\&. These behaviors might change in a future release\&. This option can\*(Aqt be used with the
FULL
option\&.
.RE
.PP
SKIP_DATABASE_STATS
.RS 4
Specifies that
\fBVACUUM\fR
should skip updating the database\-wide statistics about oldest unfrozen XIDs\&. Normally
\fBVACUUM\fR
will update these statistics once at the end of the command\&. However, this can take awhile in a database with a very large number of tables, and it will accomplish nothing unless the table that had contained the oldest unfrozen XID was among those vacuumed\&. Moreover, if multiple
\fBVACUUM\fR
commands are issued in parallel, only one of them can update the database\-wide statistics at a time\&. Therefore, if an application intends to issue a series of many
\fBVACUUM\fR
commands, it can be helpful to set this option in all but the last such command; or set it in all the commands and separately issue
VACUUM (ONLY_DATABASE_STATS)
afterwards\&.
.RE
.PP
ONLY_DATABASE_STATS
.RS 4
Specifies that
\fBVACUUM\fR
should do nothing except update the database\-wide statistics about oldest unfrozen XIDs\&. When this option is specified, the
\fItable_and_columns\fR
list must be empty, and no other option may be enabled except
VERBOSE\&.
.RE
.PP
BUFFER_USAGE_LIMIT
.RS 4
Specifies the
Buffer Access Strategy
ring buffer size for
\fBVACUUM\fR\&. This size is used to calculate the number of shared buffers which will be reused as part of this strategy\&.
0
disables use of a
Buffer Access Strategy\&. If
\fBANALYZE\fR
is also specified, the
\fBBUFFER_USAGE_LIMIT\fR
value is used for both the vacuum and analyze stages\&. This option can\*(Aqt be used with the
\fBFULL\fR
option except if
\fBANALYZE\fR
is also specified\&. When this option is not specified,
\fBVACUUM\fR
uses the value from
vacuum_buffer_usage_limit\&. Higher settings can allow
\fBVACUUM\fR
to run more quickly, but having too large a setting may cause too many other useful pages to be evicted from shared buffers\&. The minimum value is
128 kB
and the maximum value is
16 GB\&.
.RE
.PP
\fIboolean\fR
.RS 4
Specifies whether the selected option should be turned on or off\&. You can write
TRUE,
ON, or
1
to enable the option, and
FALSE,
OFF, or
0
to disable it\&. The
\fIboolean\fR
value can also be omitted, in which case
TRUE
is assumed\&.
.RE
.PP
\fIinteger\fR
.RS 4
Specifies a non\-negative integer value passed to the selected option\&.
.RE
.PP
\fIsize\fR
.RS 4
Specifies an amount of memory in kilobytes\&. Sizes may also be specified as a string containing the numerical size followed by any one of the following memory units:
B
(bytes),
kB
(kilobytes),
MB
(megabytes),
GB
(gigabytes), or
TB
(terabytes)\&.
.RE
.PP
\fItable_name\fR
.RS 4
The name (optionally schema\-qualified) of a specific table or materialized view to vacuum\&. If the specified table is a partitioned table, all of its leaf partitions are vacuumed\&.
.RE
.PP
\fIcolumn_name\fR
.RS 4
The name of a specific column to analyze\&. Defaults to all columns\&. If a column list is specified,
ANALYZE
must also be specified\&.
.RE
.SH "OUTPUTS"
.PP
When
VERBOSE
is specified,
\fBVACUUM\fR
emits progress messages to indicate which table is currently being processed\&. Various statistics about the tables are printed as well\&.
.SH "NOTES"
.PP
To vacuum a table, one must ordinarily be the table\*(Aqs owner or a superuser\&. However, database owners are allowed to vacuum all tables in their databases, except shared catalogs\&. (The restriction for shared catalogs means that a true database\-wide
\fBVACUUM\fR
can only be performed by a superuser\&.)
\fBVACUUM\fR
will skip over any tables that the calling user does not have permission to vacuum\&.
.PP
\fBVACUUM\fR
cannot be executed inside a transaction block\&.
.PP
For tables with
GIN
indexes,
\fBVACUUM\fR
(in any form) also completes any pending index insertions, by moving pending index entries to the appropriate places in the main
GIN
index structure\&. See
Section\ \&70.4.1
for details\&.
.PP
We recommend that all databases be vacuumed regularly in order to remove dead rows\&.
PostgreSQL
includes an
\(lqautovacuum\(rq
facility which can automate routine vacuum maintenance\&. For more information about automatic and manual vacuuming, see
Section\ \&25.1\&.
.PP
The
\fBFULL\fR
option is not recommended for routine use, but might be useful in special cases\&. An example is when you have deleted or updated most of the rows in a table and would like the table to physically shrink to occupy less disk space and allow faster table scans\&.
\fBVACUUM FULL\fR
will usually shrink the table more than a plain
\fBVACUUM\fR
would\&.
.PP
The
\fBPARALLEL\fR
option is used only for vacuum purposes\&. If this option is specified with the
\fBANALYZE\fR
option, it does not affect
\fBANALYZE\fR\&.
.PP
\fBVACUUM\fR
causes a substantial increase in I/O traffic, which might cause poor performance for other active sessions\&. Therefore, it is sometimes advisable to use the cost\-based vacuum delay feature\&. For parallel vacuum, each worker sleeps in proportion to the work done by that worker\&. See
Section\ \&20.4.4
for details\&.
.PP
Each backend running
\fBVACUUM\fR
without the
FULL
option will report its progress in the
pg_stat_progress_vacuum
view\&. Backends running
\fBVACUUM FULL\fR
will instead report their progress in the
pg_stat_progress_cluster
view\&. See
Section\ \&28.4.5
and
Section\ \&28.4.2
for details\&.
.SH "EXAMPLES"
.PP
To clean a single table
onek, analyze it for the optimizer and print a detailed vacuum activity report:
.sp
.if n \{\
.RS 4
.\}
.nf
VACUUM (VERBOSE, ANALYZE) onek;
.fi
.if n \{\
.RE
.\}
.SH "COMPATIBILITY"
.PP
There is no
\fBVACUUM\fR
statement in the SQL standard\&.
.SH "SEE ALSO"
\fBvacuumdb\fR(1), Section\ \&20.4.4, Section\ \&25.1.6, Section\ \&28.4.5, Section\ \&28.4.2