1VACUUM(7) PostgreSQL 14.3 Documentation VACUUM(7)
2
3
4
6 VACUUM - garbage-collect and optionally analyze a database
7
9 VACUUM [ ( option [, ...] ) ] [ table_and_columns [, ...] ]
10 VACUUM [ FULL ] [ FREEZE ] [ VERBOSE ] [ ANALYZE ] [ table_and_columns [, ...] ]
11
12 where option can be one of:
13
14 FULL [ boolean ]
15 FREEZE [ boolean ]
16 VERBOSE [ boolean ]
17 ANALYZE [ boolean ]
18 DISABLE_PAGE_SKIPPING [ boolean ]
19 SKIP_LOCKED [ boolean ]
20 INDEX_CLEANUP { AUTO | ON | OFF }
21 PROCESS_TOAST [ boolean ]
22 TRUNCATE [ boolean ]
23 PARALLEL integer
24
25 and table_and_columns is:
26
27 table_name [ ( column_name [, ...] ) ]
28
30 VACUUM reclaims storage occupied by dead tuples. In normal PostgreSQL
31 operation, tuples that are deleted or obsoleted by an update are not
32 physically removed from their table; they remain present until a VACUUM
33 is done. Therefore it's necessary to do VACUUM periodically, especially
34 on frequently-updated tables.
35
36 Without a table_and_columns list, VACUUM processes every table and
37 materialized view in the current database that the current user has
38 permission to vacuum. With a list, VACUUM processes only those
39 table(s).
40
41 VACUUM ANALYZE performs a VACUUM and then an ANALYZE for each selected
42 table. This is a handy combination form for routine maintenance
43 scripts. See ANALYZE(7) for more details about its processing.
44
45 Plain VACUUM (without FULL) simply reclaims space and makes it
46 available for re-use. This form of the command can operate in parallel
47 with normal reading and writing of the table, as an exclusive lock is
48 not obtained. However, extra space is not returned to the operating
49 system (in most cases); it's just kept available for re-use within the
50 same table. It also allows us to leverage multiple CPUs in order to
51 process indexes. This feature is known as parallel vacuum. To disable
52 this feature, one can use PARALLEL option and specify parallel workers
53 as zero. VACUUM FULL rewrites the entire contents of the table into a
54 new disk file with no extra space, allowing unused space to be returned
55 to the operating system. This form is much slower and requires an
56 ACCESS EXCLUSIVE lock on each table while it is being processed.
57
58 When the option list is surrounded by parentheses, the options can be
59 written in any order. Without parentheses, options must be specified in
60 exactly the order shown above. The parenthesized syntax was added in
61 PostgreSQL 9.0; the unparenthesized syntax is deprecated.
62
64 FULL
65 Selects “full” vacuum, which can reclaim more space, but takes much
66 longer and exclusively locks the table. This method also requires
67 extra disk space, since it writes a new copy of the table and
68 doesn't release the old copy until the operation is complete.
69 Usually this should only be used when a significant amount of space
70 needs to be reclaimed from within the table.
71
72 FREEZE
73 Selects aggressive “freezing” of tuples. Specifying FREEZE is
74 equivalent to performing VACUUM with the vacuum_freeze_min_age and
75 vacuum_freeze_table_age parameters set to zero. Aggressive freezing
76 is always performed when the table is rewritten, so this option is
77 redundant when FULL is specified.
78
79 VERBOSE
80 Prints a detailed vacuum activity report for each table.
81
82 ANALYZE
83 Updates statistics used by the planner to determine the most
84 efficient way to execute a query.
85
86 DISABLE_PAGE_SKIPPING
87 Normally, VACUUM will skip pages based on the visibility map. Pages
88 where all tuples are known to be frozen can always be skipped, and
89 those where all tuples are known to be visible to all transactions
90 may be skipped except when performing an aggressive vacuum.
91 Furthermore, except when performing an aggressive vacuum, some
92 pages may be skipped in order to avoid waiting for other sessions
93 to finish using them. This option disables all page-skipping
94 behavior, and is intended to be used only when the contents of the
95 visibility map are suspect, which should happen only if there is a
96 hardware or software issue causing database corruption.
97
98 SKIP_LOCKED
99 Specifies that VACUUM should not wait for any conflicting locks to
100 be released when beginning work on a relation: if a relation cannot
101 be locked immediately without waiting, the relation is skipped.
102 Note that even with this option, VACUUM may still block when
103 opening the relation's indexes. Additionally, VACUUM ANALYZE may
104 still block when acquiring sample rows from partitions, table
105 inheritance children, and some types of foreign tables. Also, while
106 VACUUM ordinarily processes all partitions of specified partitioned
107 tables, this option will cause VACUUM to skip all partitions if
108 there is a conflicting lock on the partitioned table.
109
110 INDEX_CLEANUP
111 Normally, VACUUM will skip index vacuuming when there are very few
112 dead tuples in the table. The cost of processing all of the table's
113 indexes is expected to greatly exceed the benefit of removing dead
114 index tuples when this happens. This option can be used to force
115 VACUUM to process indexes when there are more than zero dead
116 tuples. The default is AUTO, which allows VACUUM to skip index
117 vacuuming when appropriate. If INDEX_CLEANUP is set to ON, VACUUM
118 will conservatively remove all dead tuples from indexes. This may
119 be useful for backwards compatibility with earlier releases of
120 PostgreSQL where this was the standard behavior.
121
122 INDEX_CLEANUP can also be set to OFF to force VACUUM to always skip
123 index vacuuming, even when there are many dead tuples in the table.
124 This may be useful when it is necessary to make VACUUM run as
125 quickly as possible to avoid imminent transaction ID wraparound
126 (see Section 25.1.5). However, the wraparound failsafe mechanism
127 controlled by vacuum_failsafe_age will generally trigger
128 automatically to avoid transaction ID wraparound failure, and
129 should be preferred. If index cleanup is not performed regularly,
130 performance may suffer, because as the table is modified indexes
131 will accumulate dead tuples and the table itself will accumulate
132 dead line pointers that cannot be removed until index cleanup is
133 completed.
134
135 This option has no effect for tables that have no index and is
136 ignored if the FULL option is used. It also has no effect on the
137 transaction ID wraparound failsafe mechanism. When triggered it
138 will skip index vacuuming, even when INDEX_CLEANUP is set to ON.
139
140 PROCESS_TOAST
141 Specifies that VACUUM should attempt to process the corresponding
142 TOAST table for each relation, if one exists. This is usually the
143 desired behavior and is the default. Setting this option to false
144 may be useful when it is only necessary to vacuum the main
145 relation. This option is required when the FULL option is used.
146
147 TRUNCATE
148 Specifies that VACUUM should attempt to truncate off any empty
149 pages at the end of the table and allow the disk space for the
150 truncated pages to be returned to the operating system. This is
151 normally the desired behavior and is the default unless the
152 vacuum_truncate option has been set to false for the table to be
153 vacuumed. Setting this option to false may be useful to avoid
154 ACCESS EXCLUSIVE lock on the table that the truncation requires.
155 This option is ignored if the FULL option is used.
156
157 PARALLEL
158 Perform index vacuum and index cleanup phases of VACUUM in parallel
159 using integer background workers (for the details of each vacuum
160 phase, please refer to Table 28.39). The number of workers used to
161 perform the operation is equal to the number of indexes on the
162 relation that support parallel vacuum which is limited by the
163 number of workers specified with PARALLEL option if any which is
164 further limited by max_parallel_maintenance_workers. An index can
165 participate in parallel vacuum if and only if the size of the index
166 is more than min_parallel_index_scan_size. Please note that it is
167 not guaranteed that the number of parallel workers specified in
168 integer will be used during execution. It is possible for a vacuum
169 to run with fewer workers than specified, or even with no workers
170 at all. Only one worker can be used per index. So parallel workers
171 are launched only when there are at least 2 indexes in the table.
172 Workers for vacuum are launched before the start of each phase and
173 exit at the end of the phase. These behaviors might change in a
174 future release. This option can't be used with the FULL option.
175
176 boolean
177 Specifies whether the selected option should be turned on or off.
178 You can write TRUE, ON, or 1 to enable the option, and FALSE, OFF,
179 or 0 to disable it. The boolean value can also be omitted, in which
180 case TRUE is assumed.
181
182 integer
183 Specifies a non-negative integer value passed to the selected
184 option.
185
186 table_name
187 The name (optionally schema-qualified) of a specific table or
188 materialized view to vacuum. If the specified table is a
189 partitioned table, all of its leaf partitions are vacuumed.
190
191 column_name
192 The name of a specific column to analyze. Defaults to all columns.
193 If a column list is specified, ANALYZE must also be specified.
194
196 When VERBOSE is specified, VACUUM emits progress messages to indicate
197 which table is currently being processed. Various statistics about the
198 tables are printed as well.
199
201 To vacuum a table, one must ordinarily be the table's owner or a
202 superuser. However, database owners are allowed to vacuum all tables in
203 their databases, except shared catalogs. (The restriction for shared
204 catalogs means that a true database-wide VACUUM can only be performed
205 by a superuser.) VACUUM will skip over any tables that the calling
206 user does not have permission to vacuum.
207
208 VACUUM cannot be executed inside a transaction block.
209
210 For tables with GIN indexes, VACUUM (in any form) also completes any
211 pending index insertions, by moving pending index entries to the
212 appropriate places in the main GIN index structure. See Section 67.4.1
213 for details.
214
215 We recommend that active production databases be vacuumed frequently
216 (at least nightly), in order to remove dead rows. After adding or
217 deleting a large number of rows, it might be a good idea to issue a
218 VACUUM ANALYZE command for the affected table. This will update the
219 system catalogs with the results of all recent changes, and allow the
220 PostgreSQL query planner to make better choices in planning queries.
221
222 The FULL option is not recommended for routine use, but might be useful
223 in special cases. An example is when you have deleted or updated most
224 of the rows in a table and would like the table to physically shrink to
225 occupy less disk space and allow faster table scans. VACUUM FULL will
226 usually shrink the table more than a plain VACUUM would.
227
228 The PARALLEL option is used only for vacuum purposes. If this option is
229 specified with the ANALYZE option, it does not affect ANALYZE.
230
231 VACUUM causes a substantial increase in I/O traffic, which might cause
232 poor performance for other active sessions. Therefore, it is sometimes
233 advisable to use the cost-based vacuum delay feature. For parallel
234 vacuum, each worker sleeps in proportion to the work done by that
235 worker. See Section 20.4.4 for details.
236
237 PostgreSQL includes an “autovacuum” facility which can automate routine
238 vacuum maintenance. For more information about automatic and manual
239 vacuuming, see Section 25.1.
240
241 Each backend running VACUUM without the FULL option will report its
242 progress in the pg_stat_progress_vacuum view. Backends running VACUUM
243 FULL will instead report their progress in the pg_stat_progress_cluster
244 view. See Section 28.4.3 and Section 28.4.4 for details.
245
247 To clean a single table onek, analyze it for the optimizer and print a
248 detailed vacuum activity report:
249
250 VACUUM (VERBOSE, ANALYZE) onek;
251
253 There is no VACUUM statement in the SQL standard.
254
256 vacuumdb(1), Section 20.4.4, Section 25.1.6, Section 28.4.3,
257 Section 28.4.4
258
259
260
261PostgreSQL 14.3 2022 VACUUM(7)