1 <?xml version="1.0" encoding="UTF-8" standalone="no"?>
2 <!DOCTYPE html PUBLIC "-//W3C//DTD XHTML 1.0 Transitional//EN" "http://www.w3.org/TR/xhtml1/DTD/xhtml1-transitional.dtd"><html xmlns="http://www.w3.org/1999/xhtml"><head><meta http-equiv="Content-Type" content="text/html; charset=UTF-8" /><title>13.3. Explicit Locking</title><link rel="stylesheet" type="text/css" href="stylesheet.css" /><link rev="made" href="pgsql-docs@lists.postgresql.org" /><meta name="generator" content="DocBook XSL Stylesheets Vsnapshot" /><link rel="prev" href="transaction-iso.html" title="13.2. Transaction Isolation" /><link rel="next" href="applevel-consistency.html" title="13.4. Data Consistency Checks at the Application Level" /></head><body id="docContent" class="container-fluid col-10"><div class="navheader"><table width="100%" summary="Navigation header"><tr><th colspan="5" align="center">13.3. Explicit Locking</th></tr><tr><td width="10%" align="left"><a accesskey="p" href="transaction-iso.html" title="13.2. Transaction Isolation">Prev</a> </td><td width="10%" align="left"><a accesskey="u" href="mvcc.html" title="Chapter 13. Concurrency Control">Up</a></td><th width="60%" align="center">Chapter 13. Concurrency Control</th><td width="10%" align="right"><a accesskey="h" href="index.html" title="PostgreSQL 18.0 Documentation">Home</a></td><td width="10%" align="right"> <a accesskey="n" href="applevel-consistency.html" title="13.4. Data Consistency Checks at the Application Level">Next</a></td></tr></table><hr /></div><div class="sect1" id="EXPLICIT-LOCKING"><div class="titlepage"><div><div><h2 class="title" style="clear: both">13.3. Explicit Locking <a href="#EXPLICIT-LOCKING" class="id_link">#</a></h2></div></div></div><div class="toc"><dl class="toc"><dt><span class="sect2"><a href="explicit-locking.html#LOCKING-TABLES">13.3.1. Table-Level Locks</a></span></dt><dt><span class="sect2"><a href="explicit-locking.html#LOCKING-ROWS">13.3.2. Row-Level Locks</a></span></dt><dt><span class="sect2"><a href="explicit-locking.html#LOCKING-PAGES">13.3.3. Page-Level Locks</a></span></dt><dt><span class="sect2"><a href="explicit-locking.html#LOCKING-DEADLOCKS">13.3.4. Deadlocks</a></span></dt><dt><span class="sect2"><a href="explicit-locking.html#ADVISORY-LOCKS">13.3.5. Advisory Locks</a></span></dt></dl></div><a id="id-1.5.12.6.2" class="indexterm"></a><p>
3 <span class="productname">PostgreSQL</span> provides various lock modes
4 to control concurrent access to data in tables. These modes can
5 be used for application-controlled locking in situations where
6 <acronym class="acronym">MVCC</acronym> does not give the desired behavior. Also,
7 most <span class="productname">PostgreSQL</span> commands automatically
8 acquire locks of appropriate modes to ensure that referenced
9 tables are not dropped or modified in incompatible ways while the
10 command executes. (For example, <code class="command">TRUNCATE</code> cannot safely be
11 executed concurrently with other operations on the same table, so it
12 obtains an <code class="literal">ACCESS EXCLUSIVE</code> lock on the table to
15 To examine a list of the currently outstanding locks in a database
17 <a class="link" href="view-pg-locks.html" title="53.13. pg_locks"><code class="structname">pg_locks</code></a>
18 system view. For more information on monitoring the status of the lock
19 manager subsystem, refer to <a class="xref" href="monitoring.html" title="Chapter 27. Monitoring Database Activity">Chapter 27</a>.
20 </p><div class="sect2" id="LOCKING-TABLES"><div class="titlepage"><div><div><h3 class="title">13.3.1. Table-Level Locks <a href="#LOCKING-TABLES" class="id_link">#</a></h3></div></div></div><a id="id-1.5.12.6.5.2" class="indexterm"></a><p>
21 The list below shows the available lock modes and the contexts in
22 which they are used automatically by
23 <span class="productname">PostgreSQL</span>. You can also acquire any
24 of these locks explicitly with the command <a class="xref" href="sql-lock.html" title="LOCK"><span class="refentrytitle">LOCK</span></a>.
25 Remember that all of these lock modes are table-level locks,
26 even if the name contains the word
27 <span class="quote">“<span class="quote">row</span>”</span>; the names of the lock modes are historical.
28 To some extent the names reflect the typical usage of each lock
29 mode — but the semantics are all the same. The only real difference
30 between one lock mode and another is the set of lock modes with
31 which each conflicts (see <a class="xref" href="explicit-locking.html#TABLE-LOCK-COMPATIBILITY" title="Table 13.2. Conflicting Lock Modes">Table 13.2</a>).
32 Two transactions cannot hold locks of conflicting
33 modes on the same table at the same time. (However, a transaction
34 never conflicts with itself. For example, it might acquire
35 <code class="literal">ACCESS EXCLUSIVE</code> lock and later acquire
36 <code class="literal">ACCESS SHARE</code> lock on the same table.) Non-conflicting
37 lock modes can be held concurrently by many transactions. Notice in
38 particular that some lock modes are self-conflicting (for example,
39 an <code class="literal">ACCESS EXCLUSIVE</code> lock cannot be held by more than one
40 transaction at a time) while others are not self-conflicting (for example,
41 an <code class="literal">ACCESS SHARE</code> lock can be held by multiple transactions).
42 </p><div class="variablelist"><p class="title"><strong>Table-Level Lock Modes</strong></p><dl class="variablelist"><dt><span class="term">
43 <code class="literal">ACCESS SHARE</code> (<code class="literal">AccessShareLock</code>)
45 Conflicts with the <code class="literal">ACCESS EXCLUSIVE</code> lock
48 The <code class="command">SELECT</code> command acquires a lock of this mode on
49 referenced tables. In general, any query that only <span class="emphasis"><em>reads</em></span> a table
50 and does not modify it will acquire this lock mode.
51 </p></dd><dt><span class="term">
52 <code class="literal">ROW SHARE</code> (<code class="literal">RowShareLock</code>)
54 Conflicts with the <code class="literal">EXCLUSIVE</code> and
55 <code class="literal">ACCESS EXCLUSIVE</code> lock modes.
57 The <code class="command">SELECT</code> command acquires a lock of this mode
58 on all tables on which one of the <code class="option">FOR UPDATE</code>,
59 <code class="option">FOR NO KEY UPDATE</code>,
60 <code class="option">FOR SHARE</code>, or
61 <code class="option">FOR KEY SHARE</code> options is specified
62 (in addition to <code class="literal">ACCESS SHARE</code> locks on any other
63 tables that are referenced without any explicit
64 <code class="option">FOR ...</code> locking option).
65 </p></dd><dt><span class="term">
66 <code class="literal">ROW EXCLUSIVE</code> (<code class="literal">RowExclusiveLock</code>)
68 Conflicts with the <code class="literal">SHARE</code>, <code class="literal">SHARE ROW
69 EXCLUSIVE</code>, <code class="literal">EXCLUSIVE</code>, and
70 <code class="literal">ACCESS EXCLUSIVE</code> lock modes.
72 The commands <code class="command">UPDATE</code>,
73 <code class="command">DELETE</code>, <code class="command">INSERT</code>, and
74 <code class="command">MERGE</code>
75 acquire this lock mode on the target table (in addition to
76 <code class="literal">ACCESS SHARE</code> locks on any other referenced
77 tables). In general, this lock mode will be acquired by any
78 command that <span class="emphasis"><em>modifies data</em></span> in a table.
79 </p></dd><dt><span class="term">
80 <code class="literal">SHARE UPDATE EXCLUSIVE</code> (<code class="literal">ShareUpdateExclusiveLock</code>)
82 Conflicts with the <code class="literal">SHARE UPDATE EXCLUSIVE</code>,
83 <code class="literal">SHARE</code>, <code class="literal">SHARE ROW
84 EXCLUSIVE</code>, <code class="literal">EXCLUSIVE</code>, and
85 <code class="literal">ACCESS EXCLUSIVE</code> lock modes.
86 This mode protects a table against
87 concurrent schema changes and <code class="command">VACUUM</code> runs.
89 Acquired by <code class="command">VACUUM</code> (without <code class="option">FULL</code>),
90 <code class="command">ANALYZE</code>, <code class="command">CREATE INDEX CONCURRENTLY</code>,
91 <code class="command">CREATE STATISTICS</code>, <code class="command">COMMENT ON</code>,
92 <code class="command">REINDEX CONCURRENTLY</code>,
93 and certain <a class="link" href="sql-alterindex.html" title="ALTER INDEX"><code class="command">ALTER INDEX</code></a>
94 and <a class="link" href="sql-altertable.html" title="ALTER TABLE"><code class="command">ALTER TABLE</code></a> variants
95 (for full details see the documentation of these commands).
96 </p></dd><dt><span class="term">
97 <code class="literal">SHARE</code> (<code class="literal">ShareLock</code>)
99 Conflicts with the <code class="literal">ROW EXCLUSIVE</code>,
100 <code class="literal">SHARE UPDATE EXCLUSIVE</code>, <code class="literal">SHARE ROW
101 EXCLUSIVE</code>, <code class="literal">EXCLUSIVE</code>, and
102 <code class="literal">ACCESS EXCLUSIVE</code> lock modes.
103 This mode protects a table against concurrent data changes.
105 Acquired by <code class="command">CREATE INDEX</code>
106 (without <code class="option">CONCURRENTLY</code>).
107 </p></dd><dt><span class="term">
108 <code class="literal">SHARE ROW EXCLUSIVE</code> (<code class="literal">ShareRowExclusiveLock</code>)
110 Conflicts with the <code class="literal">ROW EXCLUSIVE</code>,
111 <code class="literal">SHARE UPDATE EXCLUSIVE</code>,
112 <code class="literal">SHARE</code>, <code class="literal">SHARE ROW
113 EXCLUSIVE</code>, <code class="literal">EXCLUSIVE</code>, and
114 <code class="literal">ACCESS EXCLUSIVE</code> lock modes.
115 This mode protects a table against concurrent data changes, and
116 is self-exclusive so that only one session can hold it at a time.
118 Acquired by <code class="command">CREATE TRIGGER</code> and some forms of
119 <a class="link" href="sql-altertable.html" title="ALTER TABLE"><code class="command">ALTER TABLE</code></a>.
120 </p></dd><dt><span class="term">
121 <code class="literal">EXCLUSIVE</code> (<code class="literal">ExclusiveLock</code>)
123 Conflicts with the <code class="literal">ROW SHARE</code>, <code class="literal">ROW
124 EXCLUSIVE</code>, <code class="literal">SHARE UPDATE
125 EXCLUSIVE</code>, <code class="literal">SHARE</code>, <code class="literal">SHARE
126 ROW EXCLUSIVE</code>, <code class="literal">EXCLUSIVE</code>, and
127 <code class="literal">ACCESS EXCLUSIVE</code> lock modes.
128 This mode allows only concurrent <code class="literal">ACCESS SHARE</code> locks,
129 i.e., only reads from the table can proceed in parallel with a
130 transaction holding this lock mode.
132 Acquired by <code class="command">REFRESH MATERIALIZED VIEW CONCURRENTLY</code>.
133 </p></dd><dt><span class="term">
134 <code class="literal">ACCESS EXCLUSIVE</code> (<code class="literal">AccessExclusiveLock</code>)
136 Conflicts with locks of all modes (<code class="literal">ACCESS
137 SHARE</code>, <code class="literal">ROW SHARE</code>, <code class="literal">ROW
138 EXCLUSIVE</code>, <code class="literal">SHARE UPDATE
139 EXCLUSIVE</code>, <code class="literal">SHARE</code>, <code class="literal">SHARE
140 ROW EXCLUSIVE</code>, <code class="literal">EXCLUSIVE</code>, and
141 <code class="literal">ACCESS EXCLUSIVE</code>).
142 This mode guarantees that the
143 holder is the only transaction accessing the table in any way.
145 Acquired by the <code class="command">DROP TABLE</code>,
146 <code class="command">TRUNCATE</code>, <code class="command">REINDEX</code>,
147 <code class="command">CLUSTER</code>, <code class="command">VACUUM FULL</code>,
148 and <code class="command">REFRESH MATERIALIZED VIEW</code> (without
149 <code class="option">CONCURRENTLY</code>)
150 commands. Many forms of <code class="command">ALTER INDEX</code> and <code class="command">ALTER TABLE</code> also acquire
151 a lock at this level. This is also the default lock mode for
152 <code class="command">LOCK TABLE</code> statements that do not specify
154 </p></dd></dl></div><div class="tip"><h3 class="title">Tip</h3><p>
155 Only an <code class="literal">ACCESS EXCLUSIVE</code> lock blocks a
156 <code class="command">SELECT</code> (without <code class="option">FOR UPDATE/SHARE</code>)
159 Once acquired, a lock is normally held until the end of the transaction. But if a
160 lock is acquired after establishing a savepoint, the lock is released
161 immediately if the savepoint is rolled back to. This is consistent with
162 the principle that <code class="command">ROLLBACK</code> cancels all effects of the
163 commands since the savepoint. The same holds for locks acquired within a
164 <span class="application">PL/pgSQL</span> exception block: an error escape from the block
165 releases locks acquired within it.
166 </p><div class="table" id="TABLE-LOCK-COMPATIBILITY"><p class="title"><strong>Table 13.2. Conflicting Lock Modes</strong></p><div class="table-contents"><table class="table" summary="Conflicting Lock Modes" border="1"><colgroup><col /><col class="lockst" /><col /><col /><col /><col /><col /><col /><col class="lockend" /></colgroup><thead><tr><th rowspan="2">Requested Lock Mode</th><th colspan="8" align="center">Existing Lock Mode</th></tr><tr><th><code class="literal">ACCESS SHARE</code></th><th><code class="literal">ROW SHARE</code></th><th><code class="literal">ROW EXCL.</code></th><th><code class="literal">SHARE UPDATE EXCL.</code></th><th><code class="literal">SHARE</code></th><th><code class="literal">SHARE ROW EXCL.</code></th><th><code class="literal">EXCL.</code></th><th><code class="literal">ACCESS EXCL.</code></th></tr></thead><tbody><tr><td><code class="literal">ACCESS SHARE</code></td><td align="center"> </td><td align="center"> </td><td align="center"> </td><td align="center"> </td><td align="center"> </td><td align="center"> </td><td align="center"> </td><td align="center">X</td></tr><tr><td><code class="literal">ROW SHARE</code></td><td align="center"> </td><td align="center"> </td><td align="center"> </td><td align="center"> </td><td align="center"> </td><td align="center"> </td><td align="center">X</td><td align="center">X</td></tr><tr><td><code class="literal">ROW EXCL.</code></td><td align="center"> </td><td align="center"> </td><td align="center"> </td><td align="center"> </td><td align="center">X</td><td align="center">X</td><td align="center">X</td><td align="center">X</td></tr><tr><td><code class="literal">SHARE UPDATE EXCL.</code></td><td align="center"> </td><td align="center"> </td><td align="center"> </td><td align="center">X</td><td align="center">X</td><td align="center">X</td><td align="center">X</td><td align="center">X</td></tr><tr><td><code class="literal">SHARE</code></td><td align="center"> </td><td align="center"> </td><td align="center">X</td><td align="center">X</td><td align="center"> </td><td align="center">X</td><td align="center">X</td><td align="center">X</td></tr><tr><td><code class="literal">SHARE ROW EXCL.</code></td><td align="center"> </td><td align="center"> </td><td align="center">X</td><td align="center">X</td><td align="center">X</td><td align="center">X</td><td align="center">X</td><td align="center">X</td></tr><tr><td><code class="literal">EXCL.</code></td><td align="center"> </td><td align="center">X</td><td align="center">X</td><td align="center">X</td><td align="center">X</td><td align="center">X</td><td align="center">X</td><td align="center">X</td></tr><tr><td><code class="literal">ACCESS EXCL.</code></td><td align="center">X</td><td align="center">X</td><td align="center">X</td><td align="center">X</td><td align="center">X</td><td align="center">X</td><td align="center">X</td><td align="center">X</td></tr></tbody></table></div></div><br class="table-break" /></div><div class="sect2" id="LOCKING-ROWS"><div class="titlepage"><div><div><h3 class="title">13.3.2. Row-Level Locks <a href="#LOCKING-ROWS" class="id_link">#</a></h3></div></div></div><p>
167 In addition to table-level locks, there are row-level locks, which
168 are listed as below with the contexts in which they are used
169 automatically by <span class="productname">PostgreSQL</span>. See
170 <a class="xref" href="explicit-locking.html#ROW-LOCK-COMPATIBILITY" title="Table 13.3. Conflicting Row-Level Locks">Table 13.3</a> for a complete table of
171 row-level lock conflicts. Note that a transaction can hold
172 conflicting locks on the same row, even in different subtransactions;
173 but other than that, two transactions can never hold conflicting locks
174 on the same row. Row-level locks do not affect data querying; they
175 block only <span class="emphasis"><em>writers and lockers</em></span> to the same
176 row. Row-level locks are released at transaction end or during
177 savepoint rollback, just like table-level locks.
179 </p><div class="variablelist"><p class="title"><strong>Row-Level Lock Modes</strong></p><dl class="variablelist"><dt><span class="term">
180 <code class="literal">FOR UPDATE</code>
182 <code class="literal">FOR UPDATE</code> causes the rows retrieved by the
183 <code class="command">SELECT</code> statement to be locked as though for
184 update. This prevents them from being locked, modified or deleted by
185 other transactions until the current transaction ends. That is,
186 other transactions that attempt <code class="command">UPDATE</code>,
187 <code class="command">DELETE</code>,
188 <code class="command">SELECT FOR UPDATE</code>,
189 <code class="command">SELECT FOR NO KEY UPDATE</code>,
190 <code class="command">SELECT FOR SHARE</code> or
191 <code class="command">SELECT FOR KEY SHARE</code>
192 of these rows will be blocked until the current transaction ends;
193 conversely, <code class="command">SELECT FOR UPDATE</code> will wait for a
194 concurrent transaction that has run any of those commands on the
196 and will then lock and return the updated row (or no row, if the
197 row was deleted). Within a <code class="literal">REPEATABLE READ</code> or
198 <code class="literal">SERIALIZABLE</code> transaction,
199 however, an error will be thrown if a row to be locked has changed
200 since the transaction started. For further discussion see
201 <a class="xref" href="applevel-consistency.html" title="13.4. Data Consistency Checks at the Application Level">Section 13.4</a>.
203 The <code class="literal">FOR UPDATE</code> lock mode
204 is also acquired by any <code class="command">DELETE</code> on a row, and also by an
205 <code class="command">UPDATE</code> that modifies the values of certain columns. Currently,
206 the set of columns considered for the <code class="command">UPDATE</code> case are those that
207 have a unique index on them that can be used in a foreign key (so partial
208 indexes and expressional indexes are not considered), but this may change
210 </p></dd><dt><span class="term">
211 <code class="literal">FOR NO KEY UPDATE</code>
213 Behaves similarly to <code class="literal">FOR UPDATE</code>, except that the lock
214 acquired is weaker: this lock will not block
215 <code class="literal">SELECT FOR KEY SHARE</code> commands that attempt to acquire
216 a lock on the same rows. This lock mode is also acquired by any
217 <code class="command">UPDATE</code> that does not acquire a <code class="literal">FOR UPDATE</code> lock.
218 </p></dd><dt><span class="term">
219 <code class="literal">FOR SHARE</code>
221 Behaves similarly to <code class="literal">FOR NO KEY UPDATE</code>, except that it
222 acquires a shared lock rather than exclusive lock on each retrieved
223 row. A shared lock blocks other transactions from performing
224 <code class="command">UPDATE</code>, <code class="command">DELETE</code>,
225 <code class="command">SELECT FOR UPDATE</code> or
226 <code class="command">SELECT FOR NO KEY UPDATE</code> on these rows, but it does not
227 prevent them from performing <code class="command">SELECT FOR SHARE</code> or
228 <code class="command">SELECT FOR KEY SHARE</code>.
229 </p></dd><dt><span class="term">
230 <code class="literal">FOR KEY SHARE</code>
232 Behaves similarly to <code class="literal">FOR SHARE</code>, except that the
233 lock is weaker: <code class="literal">SELECT FOR UPDATE</code> is blocked, but not
234 <code class="literal">SELECT FOR NO KEY UPDATE</code>. A key-shared lock blocks
235 other transactions from performing <code class="command">DELETE</code> or
236 any <code class="command">UPDATE</code> that changes the key values, but not
237 other <code class="command">UPDATE</code>, and neither does it prevent
238 <code class="command">SELECT FOR NO KEY UPDATE</code>, <code class="command">SELECT FOR SHARE</code>,
239 or <code class="command">SELECT FOR KEY SHARE</code>.
240 </p></dd></dl></div><p>
241 <span class="productname">PostgreSQL</span> doesn't remember any
242 information about modified rows in memory, so there is no limit on
243 the number of rows locked at one time. However, locking a row
244 might cause a disk write, e.g., <code class="command">SELECT FOR
245 UPDATE</code> modifies selected rows to mark them locked, and so
246 will result in disk writes.
247 </p><div class="table" id="ROW-LOCK-COMPATIBILITY"><p class="title"><strong>Table 13.3. Conflicting Row-Level Locks</strong></p><div class="table-contents"><table class="table" summary="Conflicting Row-Level Locks" border="1"><colgroup><col class="col1" /><col class="lockst" /><col class="col3" /><col class="col4" /><col class="lockend" /></colgroup><thead><tr><th rowspan="2">Requested Lock Mode</th><th colspan="4">Current Lock Mode</th></tr><tr><th>FOR KEY SHARE</th><th>FOR SHARE</th><th>FOR NO KEY UPDATE</th><th>FOR UPDATE</th></tr></thead><tbody><tr><td>FOR KEY SHARE</td><td align="center"> </td><td align="center"> </td><td align="center"> </td><td align="center">X</td></tr><tr><td>FOR SHARE</td><td align="center"> </td><td align="center"> </td><td align="center">X</td><td align="center">X</td></tr><tr><td>FOR NO KEY UPDATE</td><td align="center"> </td><td align="center">X</td><td align="center">X</td><td align="center">X</td></tr><tr><td>FOR UPDATE</td><td align="center">X</td><td align="center">X</td><td align="center">X</td><td align="center">X</td></tr></tbody></table></div></div><br class="table-break" /></div><div class="sect2" id="LOCKING-PAGES"><div class="titlepage"><div><div><h3 class="title">13.3.3. Page-Level Locks <a href="#LOCKING-PAGES" class="id_link">#</a></h3></div></div></div><p>
248 In addition to table and row locks, page-level share/exclusive locks are
249 used to control read/write access to table pages in the shared buffer
250 pool. These locks are released immediately after a row is fetched or
251 updated. Application developers normally need not be concerned with
252 page-level locks, but they are mentioned here for completeness.
253 </p></div><div class="sect2" id="LOCKING-DEADLOCKS"><div class="titlepage"><div><div><h3 class="title">13.3.4. Deadlocks <a href="#LOCKING-DEADLOCKS" class="id_link">#</a></h3></div></div></div><a id="id-1.5.12.6.8.2" class="indexterm"></a><p>
254 The use of explicit locking can increase the likelihood of
255 <em class="firstterm">deadlocks</em>, wherein two (or more) transactions each
256 hold locks that the other wants. For example, if transaction 1
257 acquires an exclusive lock on table A and then tries to acquire
258 an exclusive lock on table B, while transaction 2 has already
259 exclusive-locked table B and now wants an exclusive lock on table
260 A, then neither one can proceed.
261 <span class="productname">PostgreSQL</span> automatically detects
262 deadlock situations and resolves them by aborting one of the
263 transactions involved, allowing the other(s) to complete.
264 (Exactly which transaction will be aborted is difficult to
265 predict and should not be relied upon.)
267 Note that deadlocks can also occur as the result of row-level
268 locks (and thus, they can occur even if explicit locking is not
269 used). Consider the case in which two concurrent
270 transactions modify a table. The first transaction executes:
272 </p><pre class="screen">
273 UPDATE accounts SET balance = balance + 100.00 WHERE acctnum = 11111;
276 This acquires a row-level lock on the row with the specified
277 account number. Then, the second transaction executes:
279 </p><pre class="screen">
280 UPDATE accounts SET balance = balance + 100.00 WHERE acctnum = 22222;
281 UPDATE accounts SET balance = balance - 100.00 WHERE acctnum = 11111;
284 The first <code class="command">UPDATE</code> statement successfully
285 acquires a row-level lock on the specified row, so it succeeds in
286 updating that row. However, the second <code class="command">UPDATE</code>
287 statement finds that the row it is attempting to update has
288 already been locked, so it waits for the transaction that
289 acquired the lock to complete. Transaction two is now waiting on
290 transaction one to complete before it continues execution. Now,
291 transaction one executes:
293 </p><pre class="screen">
294 UPDATE accounts SET balance = balance - 100.00 WHERE acctnum = 22222;
297 Transaction one attempts to acquire a row-level lock on the
298 specified row, but it cannot: transaction two already holds such
299 a lock. So it waits for transaction two to complete. Thus,
300 transaction one is blocked on transaction two, and transaction
301 two is blocked on transaction one: a deadlock
302 condition. <span class="productname">PostgreSQL</span> will detect this
303 situation and abort one of the transactions.
305 The best defense against deadlocks is generally to avoid them by
306 being certain that all applications using a database acquire
307 locks on multiple objects in a consistent order. In the example
308 above, if both transactions
309 had updated the rows in the same order, no deadlock would have
310 occurred. One should also ensure that the first lock acquired on
311 an object in a transaction is the most restrictive mode that will be
312 needed for that object. If it is not feasible to verify this in
313 advance, then deadlocks can be handled on-the-fly by retrying
314 transactions that abort due to deadlocks.
316 So long as no deadlock situation is detected, a transaction seeking
317 either a table-level or row-level lock will wait indefinitely for
318 conflicting locks to be released. This means it is a bad idea for
319 applications to hold transactions open for long periods of time
320 (e.g., while waiting for user input).
321 </p></div><div class="sect2" id="ADVISORY-LOCKS"><div class="titlepage"><div><div><h3 class="title">13.3.5. Advisory Locks <a href="#ADVISORY-LOCKS" class="id_link">#</a></h3></div></div></div><a id="id-1.5.12.6.9.2" class="indexterm"></a><a id="id-1.5.12.6.9.3" class="indexterm"></a><p>
322 <span class="productname">PostgreSQL</span> provides a means for
323 creating locks that have application-defined meanings. These are
324 called <em class="firstterm">advisory locks</em>, because the system does not
325 enforce their use — it is up to the application to use them
326 correctly. Advisory locks can be useful for locking strategies
327 that are an awkward fit for the MVCC model.
328 For example, a common use of advisory locks is to emulate pessimistic
329 locking strategies typical of so-called <span class="quote">“<span class="quote">flat file</span>”</span> data
331 While a flag stored in a table could be used for the same purpose,
332 advisory locks are faster, avoid table bloat, and are automatically
333 cleaned up by the server at the end of the session.
335 There are two ways to acquire an advisory lock in
336 <span class="productname">PostgreSQL</span>: at session level or at
338 Once acquired at session level, an advisory lock is held until
339 explicitly released or the session ends. Unlike standard lock requests,
340 session-level advisory lock requests do not honor transaction semantics:
341 a lock acquired during a transaction that is later rolled back will still
342 be held following the rollback, and likewise an unlock is effective even
343 if the calling transaction fails later. A lock can be acquired multiple
344 times by its owning process; for each completed lock request there must
345 be a corresponding unlock request before the lock is actually released.
346 Transaction-level lock requests, on the other hand, behave more like
347 regular lock requests: they are automatically released at the end of the
348 transaction, and there is no explicit unlock operation. This behavior
349 is often more convenient than the session-level behavior for short-term
350 usage of an advisory lock.
351 Session-level and transaction-level lock requests for the same advisory
352 lock identifier will block each other in the expected way.
353 If a session already holds a given advisory lock, additional requests by
354 it will always succeed, even if other sessions are awaiting the lock; this
355 statement is true regardless of whether the existing lock hold and new
356 request are at session level or transaction level.
359 <span class="productname">PostgreSQL</span>, a complete list of advisory locks
360 currently held by any session can be found in the <a class="link" href="view-pg-locks.html" title="53.13. pg_locks"><code class="structname">pg_locks</code></a> system
363 Both advisory locks and regular locks are stored in a shared memory
364 pool whose size is defined by the configuration variables
365 <a class="xref" href="runtime-config-locks.html#GUC-MAX-LOCKS-PER-TRANSACTION">max_locks_per_transaction</a> and
366 <a class="xref" href="runtime-config-connection.html#GUC-MAX-CONNECTIONS">max_connections</a>.
367 Care must be taken not to exhaust this
368 memory or the server will be unable to grant any locks at all.
369 This imposes an upper limit on the number of advisory locks
370 grantable by the server, typically in the tens to hundreds of thousands
371 depending on how the server is configured.
373 In certain cases using advisory locking methods, especially in queries
374 involving explicit ordering and <code class="literal">LIMIT</code> clauses, care must be
375 taken to control the locks acquired because of the order in which SQL
376 expressions are evaluated. For example:
377 </p><pre class="screen">
378 SELECT pg_advisory_lock(id) FROM foo WHERE id = 12345; -- ok
379 SELECT pg_advisory_lock(id) FROM foo WHERE id > 12345 LIMIT 100; -- danger!
380 SELECT pg_advisory_lock(q.id) FROM
382 SELECT id FROM foo WHERE id > 12345 LIMIT 100
385 In the above queries, the second form is dangerous because the
386 <code class="literal">LIMIT</code> is not guaranteed to be applied before the locking
387 function is executed. This might cause some locks to be acquired
388 that the application was not expecting, and hence would fail to release
389 (until it ends the session).
390 From the point of view of the application, such locks
391 would be dangling, although still viewable in
392 <code class="structname">pg_locks</code>.
394 The functions provided to manipulate advisory locks are described in
395 <a class="xref" href="functions-admin.html#FUNCTIONS-ADVISORY-LOCKS" title="9.28.10. Advisory Lock Functions">Section 9.28.10</a>.
396 </p></div></div><div class="navfooter"><hr /><table width="100%" summary="Navigation footer"><tr><td width="40%" align="left"><a accesskey="p" href="transaction-iso.html" title="13.2. Transaction Isolation">Prev</a> </td><td width="20%" align="center"><a accesskey="u" href="mvcc.html" title="Chapter 13. Concurrency Control">Up</a></td><td width="40%" align="right"> <a accesskey="n" href="applevel-consistency.html" title="13.4. Data Consistency Checks at the Application Level">Next</a></td></tr><tr><td width="40%" align="left" valign="top">13.2. Transaction Isolation </td><td width="20%" align="center"><a accesskey="h" href="index.html" title="PostgreSQL 18.0 Documentation">Home</a></td><td width="40%" align="right" valign="top"> 13.4. Data Consistency Checks at the Application Level</td></tr></table></div></body></html>