2 13.3. Explicit Locking #
4 13.3.1. Table-Level Locks
5 13.3.2. Row-Level Locks
6 13.3.3. Page-Level Locks
10 PostgreSQL provides various lock modes to control concurrent access to
11 data in tables. These modes can be used for application-controlled
12 locking in situations where MVCC does not give the desired behavior.
13 Also, most PostgreSQL commands automatically acquire locks of
14 appropriate modes to ensure that referenced tables are not dropped or
15 modified in incompatible ways while the command executes. (For example,
16 TRUNCATE cannot safely be executed concurrently with other operations
17 on the same table, so it obtains an ACCESS EXCLUSIVE lock on the table
20 To examine a list of the currently outstanding locks in a database
21 server, use the pg_locks system view. For more information on
22 monitoring the status of the lock manager subsystem, refer to
25 13.3.1. Table-Level Locks #
27 The list below shows the available lock modes and the contexts in which
28 they are used automatically by PostgreSQL. You can also acquire any of
29 these locks explicitly with the command LOCK. Remember that all of
30 these lock modes are table-level locks, even if the name contains the
31 word “row”; the names of the lock modes are historical. To some extent
32 the names reflect the typical usage of each lock mode — but the
33 semantics are all the same. The only real difference between one lock
34 mode and another is the set of lock modes with which each conflicts
35 (see Table 13.2). Two transactions cannot hold locks of conflicting
36 modes on the same table at the same time. (However, a transaction never
37 conflicts with itself. For example, it might acquire ACCESS EXCLUSIVE
38 lock and later acquire ACCESS SHARE lock on the same table.)
39 Non-conflicting lock modes can be held concurrently by many
40 transactions. Notice in particular that some lock modes are
41 self-conflicting (for example, an ACCESS EXCLUSIVE lock cannot be held
42 by more than one transaction at a time) while others are not
43 self-conflicting (for example, an ACCESS SHARE lock can be held by
44 multiple transactions).
46 Table-Level Lock Modes
48 ACCESS SHARE (AccessShareLock)
49 Conflicts with the ACCESS EXCLUSIVE lock mode only.
51 The SELECT command acquires a lock of this mode on referenced
52 tables. In general, any query that only reads a table and does
53 not modify it will acquire this lock mode.
55 ROW SHARE (RowShareLock)
56 Conflicts with the EXCLUSIVE and ACCESS EXCLUSIVE lock modes.
58 The SELECT command acquires a lock of this mode on all tables on
59 which one of the FOR UPDATE, FOR NO KEY UPDATE, FOR SHARE, or
60 FOR KEY SHARE options is specified (in addition to ACCESS SHARE
61 locks on any other tables that are referenced without any
62 explicit FOR ... locking option).
64 ROW EXCLUSIVE (RowExclusiveLock)
65 Conflicts with the SHARE, SHARE ROW EXCLUSIVE, EXCLUSIVE, and
66 ACCESS EXCLUSIVE lock modes.
68 The commands UPDATE, DELETE, INSERT, and MERGE acquire this lock
69 mode on the target table (in addition to ACCESS SHARE locks on
70 any other referenced tables). In general, this lock mode will be
71 acquired by any command that modifies data in a table.
73 SHARE UPDATE EXCLUSIVE (ShareUpdateExclusiveLock)
74 Conflicts with the SHARE UPDATE EXCLUSIVE, SHARE, SHARE ROW
75 EXCLUSIVE, EXCLUSIVE, and ACCESS EXCLUSIVE lock modes. This mode
76 protects a table against concurrent schema changes and VACUUM
79 Acquired by VACUUM (without FULL), ANALYZE, CREATE INDEX
80 CONCURRENTLY, CREATE STATISTICS, COMMENT ON, REINDEX
81 CONCURRENTLY, and certain ALTER INDEX and ALTER TABLE variants
82 (for full details see the documentation of these commands).
85 Conflicts with the ROW EXCLUSIVE, SHARE UPDATE EXCLUSIVE, SHARE
86 ROW EXCLUSIVE, EXCLUSIVE, and ACCESS EXCLUSIVE lock modes. This
87 mode protects a table against concurrent data changes.
89 Acquired by CREATE INDEX (without CONCURRENTLY).
91 SHARE ROW EXCLUSIVE (ShareRowExclusiveLock)
92 Conflicts with the ROW EXCLUSIVE, SHARE UPDATE EXCLUSIVE, SHARE,
93 SHARE ROW EXCLUSIVE, EXCLUSIVE, and ACCESS EXCLUSIVE lock modes.
94 This mode protects a table against concurrent data changes, and
95 is self-exclusive so that only one session can hold it at a
98 Acquired by CREATE TRIGGER and some forms of ALTER TABLE.
100 EXCLUSIVE (ExclusiveLock)
101 Conflicts with the ROW SHARE, ROW EXCLUSIVE, SHARE UPDATE
102 EXCLUSIVE, SHARE, SHARE ROW EXCLUSIVE, EXCLUSIVE, and ACCESS
103 EXCLUSIVE lock modes. This mode allows only concurrent ACCESS
104 SHARE locks, i.e., only reads from the table can proceed in
105 parallel with a transaction holding this lock mode.
107 Acquired by REFRESH MATERIALIZED VIEW CONCURRENTLY.
109 ACCESS EXCLUSIVE (AccessExclusiveLock)
110 Conflicts with locks of all modes (ACCESS SHARE, ROW SHARE, ROW
111 EXCLUSIVE, SHARE UPDATE EXCLUSIVE, SHARE, SHARE ROW EXCLUSIVE,
112 EXCLUSIVE, and ACCESS EXCLUSIVE). This mode guarantees that the
113 holder is the only transaction accessing the table in any way.
115 Acquired by the DROP TABLE, TRUNCATE, REINDEX, CLUSTER, VACUUM
116 FULL, and REFRESH MATERIALIZED VIEW (without CONCURRENTLY)
117 commands. Many forms of ALTER INDEX and ALTER TABLE also acquire
118 a lock at this level. This is also the default lock mode for
119 LOCK TABLE statements that do not specify a mode explicitly.
123 Only an ACCESS EXCLUSIVE lock blocks a SELECT (without FOR
124 UPDATE/SHARE) statement.
126 Once acquired, a lock is normally held until the end of the
127 transaction. But if a lock is acquired after establishing a savepoint,
128 the lock is released immediately if the savepoint is rolled back to.
129 This is consistent with the principle that ROLLBACK cancels all effects
130 of the commands since the savepoint. The same holds for locks acquired
131 within a PL/pgSQL exception block: an error escape from the block
132 releases locks acquired within it.
134 Table 13.2. Conflicting Lock Modes
135 Requested Lock Mode Existing Lock Mode
136 ACCESS SHARE ROW SHARE ROW EXCL. SHARE UPDATE EXCL. SHARE SHARE ROW
137 EXCL. EXCL. ACCESS EXCL.
141 SHARE UPDATE EXCL. X X X X X
143 SHARE ROW EXCL. X X X X X X
145 ACCESS EXCL. X X X X X X X X
147 13.3.2. Row-Level Locks #
149 In addition to table-level locks, there are row-level locks, which are
150 listed as below with the contexts in which they are used automatically
151 by PostgreSQL. See Table 13.3 for a complete table of row-level lock
152 conflicts. Note that a transaction can hold conflicting locks on the
153 same row, even in different subtransactions; but other than that, two
154 transactions can never hold conflicting locks on the same row.
155 Row-level locks do not affect data querying; they block only writers
156 and lockers to the same row. Row-level locks are released at
157 transaction end or during savepoint rollback, just like table-level
163 FOR UPDATE causes the rows retrieved by the SELECT statement to
164 be locked as though for update. This prevents them from being
165 locked, modified or deleted by other transactions until the
166 current transaction ends. That is, other transactions that
167 attempt UPDATE, DELETE, SELECT FOR UPDATE, SELECT FOR NO KEY
168 UPDATE, SELECT FOR SHARE or SELECT FOR KEY SHARE of these rows
169 will be blocked until the current transaction ends; conversely,
170 SELECT FOR UPDATE will wait for a concurrent transaction that
171 has run any of those commands on the same row, and will then
172 lock and return the updated row (or no row, if the row was
173 deleted). Within a REPEATABLE READ or SERIALIZABLE transaction,
174 however, an error will be thrown if a row to be locked has
175 changed since the transaction started. For further discussion
178 The FOR UPDATE lock mode is also acquired by any DELETE on a
179 row, and also by an UPDATE that modifies the values of certain
180 columns. Currently, the set of columns considered for the UPDATE
181 case are those that have a unique index on them that can be used
182 in a foreign key (so partial indexes and expressional indexes
183 are not considered), but this may change in the future.
186 Behaves similarly to FOR UPDATE, except that the lock acquired
187 is weaker: this lock will not block SELECT FOR KEY SHARE
188 commands that attempt to acquire a lock on the same rows. This
189 lock mode is also acquired by any UPDATE that does not acquire a
193 Behaves similarly to FOR NO KEY UPDATE, except that it acquires
194 a shared lock rather than exclusive lock on each retrieved row.
195 A shared lock blocks other transactions from performing UPDATE,
196 DELETE, SELECT FOR UPDATE or SELECT FOR NO KEY UPDATE on these
197 rows, but it does not prevent them from performing SELECT FOR
198 SHARE or SELECT FOR KEY SHARE.
201 Behaves similarly to FOR SHARE, except that the lock is weaker:
202 SELECT FOR UPDATE is blocked, but not SELECT FOR NO KEY UPDATE.
203 A key-shared lock blocks other transactions from performing
204 DELETE or any UPDATE that changes the key values, but not other
205 UPDATE, and neither does it prevent SELECT FOR NO KEY UPDATE,
206 SELECT FOR SHARE, or SELECT FOR KEY SHARE.
208 PostgreSQL doesn't remember any information about modified rows in
209 memory, so there is no limit on the number of rows locked at one time.
210 However, locking a row might cause a disk write, e.g., SELECT FOR
211 UPDATE modifies selected rows to mark them locked, and so will result
214 Table 13.3. Conflicting Row-Level Locks
215 Requested Lock Mode Current Lock Mode
216 FOR KEY SHARE FOR SHARE FOR NO KEY UPDATE FOR UPDATE
219 FOR NO KEY UPDATE X X X
222 13.3.3. Page-Level Locks #
224 In addition to table and row locks, page-level share/exclusive locks
225 are used to control read/write access to table pages in the shared
226 buffer pool. These locks are released immediately after a row is
227 fetched or updated. Application developers normally need not be
228 concerned with page-level locks, but they are mentioned here for
233 The use of explicit locking can increase the likelihood of deadlocks,
234 wherein two (or more) transactions each hold locks that the other
235 wants. For example, if transaction 1 acquires an exclusive lock on
236 table A and then tries to acquire an exclusive lock on table B, while
237 transaction 2 has already exclusive-locked table B and now wants an
238 exclusive lock on table A, then neither one can proceed. PostgreSQL
239 automatically detects deadlock situations and resolves them by aborting
240 one of the transactions involved, allowing the other(s) to complete.
241 (Exactly which transaction will be aborted is difficult to predict and
242 should not be relied upon.)
244 Note that deadlocks can also occur as the result of row-level locks
245 (and thus, they can occur even if explicit locking is not used).
246 Consider the case in which two concurrent transactions modify a table.
247 The first transaction executes:
248 UPDATE accounts SET balance = balance + 100.00 WHERE acctnum = 11111;
250 This acquires a row-level lock on the row with the specified account
251 number. Then, the second transaction executes:
252 UPDATE accounts SET balance = balance + 100.00 WHERE acctnum = 22222;
253 UPDATE accounts SET balance = balance - 100.00 WHERE acctnum = 11111;
255 The first UPDATE statement successfully acquires a row-level lock on
256 the specified row, so it succeeds in updating that row. However, the
257 second UPDATE statement finds that the row it is attempting to update
258 has already been locked, so it waits for the transaction that acquired
259 the lock to complete. Transaction two is now waiting on transaction one
260 to complete before it continues execution. Now, transaction one
262 UPDATE accounts SET balance = balance - 100.00 WHERE acctnum = 22222;
264 Transaction one attempts to acquire a row-level lock on the specified
265 row, but it cannot: transaction two already holds such a lock. So it
266 waits for transaction two to complete. Thus, transaction one is blocked
267 on transaction two, and transaction two is blocked on transaction one:
268 a deadlock condition. PostgreSQL will detect this situation and abort
269 one of the transactions.
271 The best defense against deadlocks is generally to avoid them by being
272 certain that all applications using a database acquire locks on
273 multiple objects in a consistent order. In the example above, if both
274 transactions had updated the rows in the same order, no deadlock would
275 have occurred. One should also ensure that the first lock acquired on
276 an object in a transaction is the most restrictive mode that will be
277 needed for that object. If it is not feasible to verify this in
278 advance, then deadlocks can be handled on-the-fly by retrying
279 transactions that abort due to deadlocks.
281 So long as no deadlock situation is detected, a transaction seeking
282 either a table-level or row-level lock will wait indefinitely for
283 conflicting locks to be released. This means it is a bad idea for
284 applications to hold transactions open for long periods of time (e.g.,
285 while waiting for user input).
287 13.3.5. Advisory Locks #
289 PostgreSQL provides a means for creating locks that have
290 application-defined meanings. These are called advisory locks, because
291 the system does not enforce their use — it is up to the application to
292 use them correctly. Advisory locks can be useful for locking strategies
293 that are an awkward fit for the MVCC model. For example, a common use
294 of advisory locks is to emulate pessimistic locking strategies typical
295 of so-called “flat file” data management systems. While a flag stored
296 in a table could be used for the same purpose, advisory locks are
297 faster, avoid table bloat, and are automatically cleaned up by the
298 server at the end of the session.
300 There are two ways to acquire an advisory lock in PostgreSQL: at
301 session level or at transaction level. Once acquired at session level,
302 an advisory lock is held until explicitly released or the session ends.
303 Unlike standard lock requests, session-level advisory lock requests do
304 not honor transaction semantics: a lock acquired during a transaction
305 that is later rolled back will still be held following the rollback,
306 and likewise an unlock is effective even if the calling transaction
307 fails later. A lock can be acquired multiple times by its owning
308 process; for each completed lock request there must be a corresponding
309 unlock request before the lock is actually released. Transaction-level
310 lock requests, on the other hand, behave more like regular lock
311 requests: they are automatically released at the end of the
312 transaction, and there is no explicit unlock operation. This behavior
313 is often more convenient than the session-level behavior for short-term
314 usage of an advisory lock. Session-level and transaction-level lock
315 requests for the same advisory lock identifier will block each other in
316 the expected way. If a session already holds a given advisory lock,
317 additional requests by it will always succeed, even if other sessions
318 are awaiting the lock; this statement is true regardless of whether the
319 existing lock hold and new request are at session level or transaction
322 Like all locks in PostgreSQL, a complete list of advisory locks
323 currently held by any session can be found in the pg_locks system view.
325 Both advisory locks and regular locks are stored in a shared memory
326 pool whose size is defined by the configuration variables
327 max_locks_per_transaction and max_connections. Care must be taken not
328 to exhaust this memory or the server will be unable to grant any locks
329 at all. This imposes an upper limit on the number of advisory locks
330 grantable by the server, typically in the tens to hundreds of thousands
331 depending on how the server is configured.
333 In certain cases using advisory locking methods, especially in queries
334 involving explicit ordering and LIMIT clauses, care must be taken to
335 control the locks acquired because of the order in which SQL
336 expressions are evaluated. For example:
337 SELECT pg_advisory_lock(id) FROM foo WHERE id = 12345; -- ok
338 SELECT pg_advisory_lock(id) FROM foo WHERE id > 12345 LIMIT 100; -- danger!
339 SELECT pg_advisory_lock(q.id) FROM
341 SELECT id FROM foo WHERE id > 12345 LIMIT 100
344 In the above queries, the second form is dangerous because the LIMIT is
345 not guaranteed to be applied before the locking function is executed.
346 This might cause some locks to be acquired that the application was not
347 expecting, and hence would fail to release (until it ends the session).
348 From the point of view of the application, such locks would be
349 dangling, although still viewable in pg_locks.
351 The functions provided to manipulate advisory locks are described in