1VACUUM(7) SQL Commands VACUUM(7)
2
3
4
6 VACUUM - garbage-collect and optionally analyze a database
7
8
10 VACUUM [ FULL ] [ FREEZE ] [ VERBOSE ] [ table ]
11 VACUUM [ FULL ] [ FREEZE ] [ VERBOSE ] ANALYZE [ table [ (column [, ...] ) ] ]
12
13
15 VACUUM reclaims storage occupied by dead tuples. In normal PostgreSQL
16 operation, tuples that are deleted or obsoleted by an update are not
17 physically removed from their table; they remain present until a VACUUM
18 is done. Therefore it's necessary to do VACUUM periodically, especially
19 on frequently-updated tables.
20
21 With no parameter, VACUUM processes every table in the current database
22 that the current user has permission to vacuum. With a parameter, VAC‐
23 UUM processes only that table.
24
25 VACUUM ANALYZE performs a VACUUM and then an ANALYZE for each selected
26 table. This is a handy combination form for routine maintenance
27 scripts. See ANALYZE [analyze(7)] for more details about its process‐
28 ing.
29
30 Plain VACUUM (without FULL) simply reclaims space and makes it avail‐
31 able for re-use. This form of the command can operate in parallel with
32 normal reading and writing of the table, as an exclusive lock is not
33 obtained. VACUUM FULL does more extensive processing, including moving
34 of tuples across blocks to try to compact the table to the minimum num‐
35 ber of disk blocks. This form is much slower and requires an exclusive
36 lock on each table while it is being processed.
37
39 FULL Selects ``full'' vacuum, which can reclaim more space, but takes
40 much longer and exclusively locks the table.
41
42 FREEZE Selects aggressive ``freezing'' of tuples. Specifying FREEZE is
43 equivalent to performing VACUUM with the vacuum_freeze_min_age
44 parameter set to zero. The FREEZE option is deprecated and will
45 be removed in a future release; set the parameter instead.
46
47 VERBOSE
48 Prints a detailed vacuum activity report for each table.
49
50 ANALYZE
51 Updates statistics used by the planner to determine the most
52 efficient way to execute a query.
53
54 table The name (optionally schema-qualified) of a specific table to
55 vacuum. Defaults to all tables in the current database.
56
57 column The name of a specific column to analyze. Defaults to all col‐
58 umns.
59
61 When VERBOSE is specified, VACUUM emits progress messages to indicate
62 which table is currently being processed. Various statistics about the
63 tables are printed as well.
64
66 To vacuum a table, one must ordinarily be the table's owner or a supe‐
67 ruser. However, database owners are allowed to vacuum all tables in
68 their databases, except shared catalogs. (The restriction for shared
69 catalogs means that a true database-wide VACUUM can only be performed
70 by a superuser.) VACUUM will skip over any tables that the calling
71 user does not have permission to vacuum.
72
73 VACUUM cannot be executed inside a transaction block.
74
75 For tables with GIN indexes, VACUUM (in any form) also completes any
76 pending index insertions, by moving pending index entries to the appro‐
77 priate places in the main GIN index structure. See in the documentation
78 for details.
79
80 We recommend that active production databases be vacuumed frequently
81 (at least nightly), in order to remove dead rows. After adding or
82 deleting a large number of rows, it might be a good idea to issue a
83 VACUUM ANALYZE command for the affected table. This will update the
84 system catalogs with the results of all recent changes, and allow the
85 PostgreSQL query planner to make better choices in planning queries.
86
87 The FULL option is not recommended for routine use, but might be useful
88 in special cases. An example is when you have deleted or updated most
89 of the rows in a table and would like the table to physically shrink to
90 occupy less disk space and allow faster table scans. VACUUM FULL will
91 usually shrink the table more than a plain VACUUM would. The FULL
92 option does not shrink indexes; a periodic REINDEX is still recom‐
93 mended. In fact, it is often faster to drop all indexes, VACUUM FULL,
94 and recreate the indexes.
95
96 VACUUM causes a substantial increase in I/O traffic, which might cause
97 poor performance for other active sessions. Therefore, it is sometimes
98 advisable to use the cost-based vacuum delay feature. See in the docu‐
99 mentation for details.
100
101 PostgreSQL includes an ``autovacuum'' facility which can automate rou‐
102 tine vacuum maintenance. For more information about automatic and man‐
103 ual vacuuming, see in the documentation.
104
106 The following is an example from running VACUUM on a table in the
107 regression database:
108
109 regression=# VACUUM VERBOSE ANALYZE onek;
110 INFO: vacuuming "public.onek"
111 INFO: index "onek_unique1" now contains 1000 tuples in 14 pages
112 DETAIL: 3000 index tuples were removed.
113 0 index pages have been deleted, 0 are currently reusable.
114 CPU 0.01s/0.08u sec elapsed 0.18 sec.
115 INFO: index "onek_unique2" now contains 1000 tuples in 16 pages
116 DETAIL: 3000 index tuples were removed.
117 0 index pages have been deleted, 0 are currently reusable.
118 CPU 0.00s/0.07u sec elapsed 0.23 sec.
119 INFO: index "onek_hundred" now contains 1000 tuples in 13 pages
120 DETAIL: 3000 index tuples were removed.
121 0 index pages have been deleted, 0 are currently reusable.
122 CPU 0.01s/0.08u sec elapsed 0.17 sec.
123 INFO: index "onek_stringu1" now contains 1000 tuples in 48 pages
124 DETAIL: 3000 index tuples were removed.
125 0 index pages have been deleted, 0 are currently reusable.
126 CPU 0.01s/0.09u sec elapsed 0.59 sec.
127 INFO: "onek": removed 3000 tuples in 108 pages
128 DETAIL: CPU 0.01s/0.06u sec elapsed 0.07 sec.
129 INFO: "onek": found 3000 removable, 1000 nonremovable tuples in 143 pages
130 DETAIL: 0 dead tuples cannot be removed yet.
131 There were 0 unused item pointers.
132 0 pages are entirely empty.
133 CPU 0.07s/0.39u sec elapsed 1.56 sec.
134 INFO: analyzing "public.onek"
135 INFO: "onek": 36 pages, 1000 rows sampled, 1000 estimated total rows
136 VACUUM
137
138
140 There is no VACUUM statement in the SQL standard.
141
143 vacuumdb [vacuumdb(1)], in the documentation, in the documentation
144
145
146
147SQL - Language Statements 2014-02-17 VACUUM(7)