gooderp18绿色标准版
You can not select more than 25 topics Topics must start with a letter or number, can include dashes ('-') and can be up to 35 characters long.

391 lines
32KB

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