2 F.1. amcheck — tools to verify table and index consistency #
5 F.1.2. Optional heapallindexed Verification
6 F.1.3. Using amcheck Effectively
7 F.1.4. Repairing Corruption
9 The amcheck module provides functions that allow you to verify the
10 logical consistency of the structure of relations.
12 The B-Tree checking functions verify various invariants in the
13 structure of the representation of particular relations. The
14 correctness of the access method functions behind index scans and other
15 important operations relies on these invariants always holding. For
16 example, certain functions verify, among other things, that all B-Tree
17 pages have items in “logical” order (e.g., for B-Tree indexes on text,
18 index tuples should be in collated lexical order). If that particular
19 invariant somehow fails to hold, we can expect binary searches on the
20 affected page to incorrectly guide index scans, resulting in wrong
21 answers to SQL queries. If the structure appears to be valid, no error
22 is raised. While these checking functions are run, the search_path is
23 temporarily changed to pg_catalog, pg_temp.
25 Verification is performed using the same procedures as those used by
26 index scans themselves, which may be user-defined operator class code.
27 For example, B-Tree index verification relies on comparisons made with
28 one or more B-Tree support function 1 routines. See Section 36.16.3 for
29 details of operator class support functions.
31 Unlike the B-Tree checking functions which report corruption by raising
32 errors, the heap checking function verify_heapam checks a table and
33 attempts to return a set of rows, one row per corruption detected.
34 Despite this, if facilities that verify_heapam relies upon are
35 themselves corrupted, the function may be unable to continue and may
36 instead raise an error.
38 Permission to execute amcheck functions may be granted to
39 non-superusers, but before granting such permissions careful
40 consideration should be given to data security and privacy concerns.
41 Although the corruption reports generated by these functions do not
42 focus on the contents of the corrupted data so much as on the structure
43 of that data and the nature of the corruptions found, an attacker who
44 gains permission to execute these functions, particularly if the
45 attacker can also induce corruption, might be able to infer something
46 of the data itself from such messages.
50 bt_index_check(index regclass, heapallindexed boolean, checkunique
52 bt_index_check tests that its target, a B-Tree index, respects a
53 variety of invariants. Example usage:
55 test=# SELECT bt_index_check(index => c.oid, heapallindexed => i.indisunique),
59 JOIN pg_opclass op ON i.indclass[0] = op.oid
60 JOIN pg_am am ON op.opcmethod = am.oid
61 JOIN pg_class c ON i.indexrelid = c.oid
62 JOIN pg_namespace n ON c.relnamespace = n.oid
63 WHERE am.amname = 'btree' AND n.nspname = 'pg_catalog'
64 -- Don't check temp tables, which may be from another session:
65 AND c.relpersistence != 't'
66 -- Function may throw an error when this is omitted:
67 AND c.relkind = 'i' AND i.indisready AND i.indisvalid
68 ORDER BY c.relpages DESC LIMIT 10;
69 bt_index_check | relname | relpages
70 ----------------+---------------------------------+----------
71 | pg_depend_reference_index | 43
72 | pg_depend_depender_index | 40
73 | pg_proc_proname_args_nsp_index | 31
74 | pg_description_o_c_o_index | 21
75 | pg_attribute_relid_attnam_index | 14
76 | pg_proc_oid_index | 10
77 | pg_attribute_relid_attnum_index | 9
78 | pg_amproc_fam_proc_index | 5
79 | pg_amop_opr_fam_index | 5
80 | pg_amop_fam_strat_index | 5
83 This example shows a session that performs verification of the
84 10 largest catalog indexes in the database “test”. Verification
85 of the presence of heap tuples as index tuples is requested for
86 the subset that are unique indexes. Since no error is raised,
87 all indexes tested appear to be logically consistent. Naturally,
88 this query could easily be changed to call bt_index_check for
89 every index in the database where verification is supported.
91 bt_index_check acquires an AccessShareLock on the target index
92 and the heap relation it belongs to. This lock mode is the same
93 lock mode acquired on relations by simple SELECT statements.
94 bt_index_check does not verify invariants that span child/parent
95 relationships, but will verify the presence of all heap tuples
96 as index tuples within the index when heapallindexed is true.
97 When checkunique is true bt_index_check will check that no more
98 than one among duplicate entries in unique index is visible.
99 When a routine, lightweight test for corruption is required in a
100 live production environment, using bt_index_check often provides
101 the best trade-off between thoroughness of verification and
102 limiting the impact on application performance and availability.
104 bt_index_parent_check(index regclass, heapallindexed boolean,
105 rootdescend boolean, checkunique boolean) returns void
106 bt_index_parent_check tests that its target, a B-Tree index,
107 respects a variety of invariants. Optionally, when the
108 heapallindexed argument is true, the function verifies the
109 presence of all heap tuples that should be found within the
110 index. When checkunique is true bt_index_parent_check will check
111 that no more than one among duplicate entries in unique index is
112 visible. When the optional rootdescend argument is true,
113 verification re-finds tuples on the leaf level by performing a
114 new search from the root page for each tuple. The checks that
115 can be performed by bt_index_parent_check are a superset of the
116 checks that can be performed by bt_index_check.
117 bt_index_parent_check can be thought of as a more thorough
118 variant of bt_index_check: unlike bt_index_check,
119 bt_index_parent_check also checks invariants that span
120 parent/child relationships, including checking that there are no
121 missing downlinks in the index structure. bt_index_parent_check
122 follows the general convention of raising an error if it finds a
123 logical inconsistency or other problem.
125 A ShareLock is required on the target index by
126 bt_index_parent_check (a ShareLock is also acquired on the heap
127 relation). These locks prevent concurrent data modification from
128 INSERT, UPDATE, and DELETE commands. The locks also prevent the
129 underlying relation from being concurrently processed by VACUUM,
130 as well as all other utility commands. Note that the function
131 holds locks only while running, not for the entire transaction.
133 bt_index_parent_check's additional verification is more likely
134 to detect various pathological cases. These cases may involve an
135 incorrectly implemented B-Tree operator class used by the index
136 that is checked, or, hypothetically, undiscovered bugs in the
137 underlying B-Tree index access method code. Note that
138 bt_index_parent_check cannot be used when hot standby mode is
139 enabled (i.e., on read-only physical replicas), unlike
142 gin_index_check(index regclass) returns void
143 gin_index_check tests that its target GIN index has consistent
144 parent-child tuples relations (no parent tuples require tuple
145 adjustment) and page graph respects balanced-tree invariants
146 (internal pages reference only leaf page or only internal
151 bt_index_check and bt_index_parent_check both output log messages about
152 the verification process at DEBUG1 and DEBUG2 severity levels. These
153 messages provide detailed information about the verification process
154 that may be of interest to PostgreSQL developers. Advanced users may
155 also find this information helpful, since it provides additional
156 context should verification actually detect an inconsistency. Running:
157 SET client_min_messages = DEBUG1;
159 in an interactive psql session before running a verification query will
160 display messages about the progress of verification with a manageable
163 verify_heapam(relation regclass, on_error_stop boolean, check_toast
164 boolean, skip text, startblock bigint, endblock bigint, blkno
165 OUT bigint, offnum OUT integer, attnum OUT integer, msg OUT
166 text) returns setof record
167 Checks a table, sequence, or materialized view for structural
168 corruption, where pages in the relation contain data that is
169 invalidly formatted, and for logical corruption, where pages are
170 structurally valid but inconsistent with the rest of the
173 The following optional arguments are recognized:
176 If true, corruption checking stops at the end of the first
177 block in which any corruptions are found.
182 If true, toasted values are checked against the target
183 relation's TOAST table.
185 This option is known to be slow. Also, if the toast table
186 or its index is corrupt, checking it against toast values
187 could conceivably crash the server, although in many cases
188 this would just produce an error.
193 If not none, corruption checking skips blocks that are
194 marked as all-visible or all-frozen, as specified. Valid
195 options are all-visible, all-frozen and none.
200 If specified, corruption checking begins at the specified
201 block, skipping all previous blocks. It is an error to
202 specify a startblock outside the range of blocks in the
205 By default, checking begins at the first block.
208 If specified, corruption checking ends at the specified
209 block, skipping all remaining blocks. It is an error to
210 specify an endblock outside the range of blocks in the
213 By default, all blocks are checked.
215 For each corruption detected, verify_heapam returns a row with
216 the following columns:
219 The number of the block containing the corrupt page.
222 The OffsetNumber of the corrupt tuple.
225 The attribute number of the corrupt column in the tuple,
226 if the corruption is specific to a column and not the
230 A message describing the problem detected.
232 F.1.2. Optional heapallindexed Verification #
234 When the heapallindexed argument to B-Tree verification functions is
235 true, an additional phase of verification is performed against the
236 table associated with the target index relation. This consists of a
237 “dummy” CREATE INDEX operation, which checks for the presence of all
238 hypothetical new index tuples against a temporary, in-memory
239 summarizing structure (this is built when needed during the basic first
240 phase of verification). The summarizing structure “fingerprints” every
241 tuple found within the target index. The high level principle behind
242 heapallindexed verification is that a new index that is equivalent to
243 the existing, target index must only have entries that can be found in
244 the existing structure.
246 The additional heapallindexed phase adds significant overhead:
247 verification will typically take several times longer. However, there
248 is no change to the relation-level locks acquired when heapallindexed
249 verification is performed.
251 The summarizing structure is bound in size by maintenance_work_mem. In
252 order to ensure that there is no more than a 2% probability of failure
253 to detect an inconsistency for each heap tuple that should be
254 represented in the index, approximately 2 bytes of memory are needed
255 per tuple. As less memory is made available per tuple, the probability
256 of missing an inconsistency slowly increases. This approach limits the
257 overhead of verification significantly, while only slightly reducing
258 the probability of detecting a problem, especially for installations
259 where verification is treated as a routine maintenance task. Any single
260 absent or malformed tuple has a new opportunity to be detected with
261 each new verification attempt.
263 F.1.3. Using amcheck Effectively #
265 amcheck can be effective at detecting various types of failure modes
266 that data checksums will fail to catch. These include:
267 * Structural inconsistencies caused by incorrect operator class
269 This includes issues caused by the comparison rules of operating
270 system collations changing. Comparisons of datums of a collatable
271 type like text must be immutable (just as all comparisons used for
272 B-Tree index scans must be immutable), which implies that operating
273 system collation rules must never change. Though rare, updates to
274 operating system collation rules can cause these issues. More
275 commonly, an inconsistency in the collation order between a primary
276 server and a standby server is implicated, possibly because the
277 major operating system version in use is inconsistent. Such
278 inconsistencies will generally only arise on standby servers, and
279 so can generally only be detected on standby servers.
280 If a problem like this arises, it may not affect each individual
281 index that is ordered using an affected collation, simply because
282 indexed values might happen to have the same absolute ordering
283 regardless of the behavioral inconsistency. See Section 23.1 and
284 Section 23.2 for further details about how PostgreSQL uses
285 operating system locales and collations.
286 * Structural inconsistencies between indexes and the heap relations
287 that are indexed (when heapallindexed verification is performed).
288 There is no cross-checking of indexes against their heap relation
289 during normal operation. Symptoms of heap corruption can be subtle.
290 * Corruption caused by hypothetical undiscovered bugs in the
291 underlying PostgreSQL access method code, sort code, or transaction
293 Automatic verification of the structural integrity of indexes plays
294 a role in the general testing of new or proposed PostgreSQL
295 features that could plausibly allow a logical inconsistency to be
296 introduced. Verification of table structure and associated
297 visibility and transaction status information plays a similar role.
298 One obvious testing strategy is to call amcheck functions
299 continuously when running the standard regression tests. See
300 Section 31.1 for details on running the tests.
301 * File system or storage subsystem faults when data checksums are
303 Note that amcheck examines a page as represented in some shared
304 memory buffer at the time of verification if there is only a shared
305 buffer hit when accessing the block. Consequently, amcheck does not
306 necessarily examine data read from the file system at the time of
307 verification. Note that when checksums are enabled, amcheck may
308 raise an error due to a checksum failure when a corrupt block is
310 * Corruption caused by faulty RAM, or the broader memory subsystem.
311 PostgreSQL does not protect against correctable memory errors and
312 it is assumed you will operate using RAM that uses industry
313 standard Error Correcting Codes (ECC) or better protection.
314 However, ECC memory is typically only immune to single-bit errors,
315 and should not be assumed to provide absolute protection against
316 failures that result in memory corruption.
317 When heapallindexed verification is performed, there is generally a
318 greatly increased chance of detecting single-bit errors, since
319 strict binary equality is tested, and the indexed attributes within
322 Structural corruption can happen due to faulty storage hardware, or
323 relation files being overwritten or modified by unrelated software.
324 This kind of corruption can also be detected with data page checksums.
326 Relation pages which are correctly formatted, internally consistent,
327 and correct relative to their own internal checksums may still contain
328 logical corruption. As such, this kind of corruption cannot be detected
329 with checksums. Examples include toasted values in the main table which
330 lack a corresponding entry in the toast table, and tuples in the main
331 table with a Transaction ID that is older than the oldest valid
332 Transaction ID in the database or cluster.
334 Multiple causes of logical corruption have been observed in production
335 systems, including bugs in the PostgreSQL server software, faulty and
336 ill-conceived backup and restore tools, and user error.
338 Corrupt relations are most concerning in live production environments,
339 precisely the same environments where high risk activities are least
340 welcome. For this reason, verify_heapam has been designed to diagnose
341 corruption without undue risk. It cannot guard against all causes of
342 backend crashes, as even executing the calling query could be unsafe on
343 a badly corrupted system. Access to catalog tables is performed and
344 could be problematic if the catalogs themselves are corrupted.
346 In general, amcheck can only prove the presence of corruption; it
347 cannot prove its absence.
349 F.1.4. Repairing Corruption #
351 No error concerning corruption raised by amcheck should ever be a false
352 positive. amcheck raises errors in the event of conditions that, by
353 definition, should never happen, and so careful analysis of amcheck
354 errors is often required.
356 There is no general method of repairing problems that amcheck detects.
357 An explanation for the root cause of an invariant violation should be
358 sought. pageinspect may play a useful role in diagnosing corruption
359 that amcheck detects. A REINDEX may not be effective in repairing