1 2 3 4 5 6 7 8 9 10 11 12 13 14 15 16 17 18 19 20 21 22 23 24 25 26 27 28 29 30 31 32 33 34 35 36 37 38 39 40 41 42 43 44 45 46 47 48 49 50 51 52 53 54 55 56 57 58 59 60 61 62 63 64 65 66 67 68 69 70 71 72 73 74 75 76 77 78 79 80 81 82 83 84 85 86 87 88 89 90 91 92 93 94 95 96 97 98 99 100 101 102 103 104 105 106 107 108 109 110 111 112 113 114 115 116 117 118 119 120 121 122 123 124 125 126 127 128 129 130 131 132 133 134 135 136 137 138 139 140 141 142 143 144 145 146 147 148 149 150 151 152 153 154 155 156 157 158 159 160 161 162 163 164 165 166 167 168 169 170 171 172 173 174 175 176 177 178 179 180 181 182 183 184 185 186 187 188
|
<html>
<head>
<meta http-equiv="Content-Type" content="text/html; charset=ISO-8859-1">
<title>LOCK</title>
<link rel="stylesheet" href="stylesheet.css" type="text/css">
<link rev="made" href="pgsql-docs@postgresql.org">
<meta name="generator" content="DocBook XSL Stylesheets V1.70.0">
<link rel="start" href="index.html" title="PostgreSQL 8.1.4 Documentation">
<link rel="up" href="sql-commands.html" title="SQL Commands">
<link rel="prev" href="sql-load.html" title="LOAD">
<link rel="next" href="sql-move.html" title="MOVE">
<link rel="copyright" href="ln-legalnotice.html" title="Legal Notice">
</head>
<body bgcolor="white" text="black" link="#0000FF" vlink="#840084" alink="#0000FF"><div class="refentry" lang="en">
<a name="sql-lock"></a><div class="titlepage"></div>
<div class="refnamediv">
<h2>Name</h2>
<p>LOCK — lock a table</p>
</div>
<a name="id778022"></a><div class="refsynopsisdiv">
<h2>Synopsis</h2>
<pre class="synopsis">LOCK [ TABLE ] <em class="replaceable"><code>name</code></em> [, ...] [ IN <em class="replaceable"><code>lockmode</code></em> MODE ] [ NOWAIT ]
where <em class="replaceable"><code>lockmode</code></em> is one of:
ACCESS SHARE | ROW SHARE | ROW EXCLUSIVE | SHARE UPDATE EXCLUSIVE
| SHARE | SHARE ROW EXCLUSIVE | EXCLUSIVE | ACCESS EXCLUSIVE</pre>
</div>
<div class="refsect1" lang="en">
<a name="id778062"></a><h2>Description</h2>
<p> <code class="command">LOCK TABLE</code> obtains a table-level lock, waiting
if necessary for any conflicting locks to be released. If
<code class="literal">NOWAIT</code> is specified, <code class="command">LOCK
TABLE</code> does not wait to acquire the desired lock: if it
cannot be acquired immediately, the command is aborted and an
error is emitted. Once obtained, the lock is held for the
remainder of the current transaction. (There is no <code class="command">UNLOCK
TABLE</code> command; locks are always released at transaction
end.)
</p>
<p> When acquiring locks automatically for commands that reference
tables, <span class="productname">PostgreSQL</span> always uses the least
restrictive lock mode possible. <code class="command">LOCK TABLE</code>
provides for cases when you might need more restrictive locking.
For example, suppose an application runs a transaction at the
Read Committed isolation level and needs to ensure that data in a
table remains stable for the duration of the transaction. To
achieve this you could obtain <code class="literal">SHARE</code> lock mode over the
table before querying. This will prevent concurrent data changes
and ensure subsequent reads of the table see a stable view of
committed data, because <code class="literal">SHARE</code> lock mode conflicts with
the <code class="literal">ROW EXCLUSIVE</code> lock acquired by writers, and your
<code class="command">LOCK TABLE <em class="replaceable"><code>name</code></em> IN SHARE MODE</code>
statement will wait until any concurrent holders of <code class="literal">ROW
EXCLUSIVE</code> mode locks commit or roll back. Thus, once you
obtain the lock, there are no uncommitted writes outstanding;
furthermore none can begin until you release the lock.
</p>
<p> To achieve a similar effect when running a transaction at the Serializable
isolation level, you have to execute the <code class="command">LOCK TABLE</code> statement
before executing any <code class="command">SELECT</code> or data modification statement.
A serializable transaction's view of data will be frozen when its first
<code class="command">SELECT</code> or data modification statement begins. A <code class="command">LOCK
TABLE</code> later in the transaction will still prevent concurrent writes
[mdash ] but it won't ensure that what the transaction reads corresponds to
the latest committed values.
</p>
<p> If a transaction of this sort is going to change the data in the
table, then it should use <code class="literal">SHARE ROW EXCLUSIVE</code> lock mode
instead of <code class="literal">SHARE</code> mode. This ensures that only one
transaction of this type runs at a time. Without this, a deadlock
is possible: two transactions might both acquire <code class="literal">SHARE</code>
mode, and then be unable to also acquire <code class="literal">ROW EXCLUSIVE</code>
mode to actually perform their updates. (Note that a transaction's
own locks never conflict, so a transaction can acquire <code class="literal">ROW
EXCLUSIVE</code> mode when it holds <code class="literal">SHARE</code> mode [mdash ] but not
if anyone else holds <code class="literal">SHARE</code> mode.) To avoid deadlocks,
make sure all transactions acquire locks on the same objects in the
same order, and if multiple lock modes are involved for a single
object, then transactions should always acquire the most
restrictive mode first.
</p>
<p> More information about the lock modes and locking strategies can be
found in <a href="explicit-locking.html" title="12.3.Explicit Locking">Section12.3, “Explicit Locking”</a>.
</p>
</div>
<div class="refsect1" lang="en">
<a name="id778283"></a><h2>Parameters</h2>
<div class="variablelist"><dl>
<dt><span class="term"><em class="replaceable"><code>name</code></em></span></dt>
<dd>
<p> The name (optionally schema-qualified) of an existing table to
lock.
</p>
<p> The command <code class="literal">LOCK TABLE a, b;</code> is equivalent to
<code class="literal">LOCK TABLE a; LOCK TABLE b;</code>. The tables are locked
one-by-one in the order specified in the <code class="command">LOCK
TABLE</code> command.
</p>
</dd>
<dt><span class="term"><em class="replaceable"><code>lockmode</code></em></span></dt>
<dd>
<p> The lock mode specifies which locks this lock conflicts with.
Lock modes are described in <a href="explicit-locking.html" title="12.3.Explicit Locking">Section12.3, “Explicit Locking”</a>.
</p>
<p> If no lock mode is specified, then <code class="literal">ACCESS
EXCLUSIVE</code>, the most restrictive mode, is used.
</p>
</dd>
<dt><span class="term"><code class="literal">NOWAIT</code></span></dt>
<dd><p> Specifies that <code class="command">LOCK TABLE</code> should not wait for
any conflicting locks to be released: if the specified lock(s)
cannot be acquired immediately without waiting, the transaction
is aborted.
</p></dd>
</dl></div>
</div>
<div class="refsect1" lang="en">
<a name="id778378"></a><h2>Notes</h2>
<p> <code class="literal">LOCK TABLE ... IN ACCESS SHARE MODE</code> requires <code class="literal">SELECT</code>
privileges on the target table. All other forms of <code class="command">LOCK</code>
require <code class="literal">UPDATE</code> and/or <code class="literal">DELETE</code> privileges.
</p>
<p> <code class="command">LOCK TABLE</code> is useful only inside a transaction
block (<code class="command">BEGIN</code>/<code class="command">COMMIT</code> pair), since the lock
is dropped as soon as the transaction ends. A <code class="command">LOCK
TABLE</code> command appearing outside any transaction block forms a
self-contained transaction, so the lock will be dropped as soon as
it is obtained.
</p>
<p> <code class="command">LOCK TABLE</code> only deals with table-level locks, and so
the mode names involving <code class="literal">ROW</code> are all misnomers. These
mode names should generally be read as indicating the intention of
the user to acquire row-level locks within the locked table. Also,
<code class="literal">ROW EXCLUSIVE</code> mode is a sharable table lock. Keep in
mind that all the lock modes have identical semantics so far as
<code class="command">LOCK TABLE</code> is concerned, differing only in the rules
about which modes conflict with which. For information on how to
acquire an actual row-level lock, see <a href="explicit-locking.html#locking-rows" title="12.3.2.Row-Level Locks">Section12.3.2, “Row-Level Locks”</a>
and the <a href="sql-select.html#sql-for-update-share"><code class="literal">FOR UPDATE</code>/<code class="literal">FOR SHARE</code> Clause</a> in the <code class="command">SELECT</code>
reference documentation.
</p>
</div>
<div class="refsect1" lang="en">
<a name="id778519"></a><h2>Examples</h2>
<p> Obtain a <code class="literal">SHARE</code> lock on a primary key table when going to perform
inserts into a foreign key table:
</p>
<pre class="programlisting">BEGIN WORK;
LOCK TABLE films IN SHARE MODE;
SELECT id FROM films
WHERE name = 'Star Wars: Episode I - The Phantom Menace';
-- Do ROLLBACK if record was not returned
INSERT INTO films_user_comments VALUES
(_id_, 'GREAT! I was waiting for it for so long!');
COMMIT WORK;</pre>
<p>
</p>
<p> Take a <code class="literal">SHARE ROW EXCLUSIVE</code> lock on a primary key table when going to perform
a delete operation:
</p>
<pre class="programlisting">BEGIN WORK;
LOCK TABLE films IN SHARE ROW EXCLUSIVE MODE;
DELETE FROM films_user_comments WHERE id IN
(SELECT id FROM films WHERE rating < 5);
DELETE FROM films WHERE rating < 5;
COMMIT WORK;</pre>
<p>
</p>
</div>
<div class="refsect1" lang="en">
<a name="id778566"></a><h2>Compatibility</h2>
<p> There is no <code class="command">LOCK TABLE</code> in the SQL standard,
which instead uses <code class="command">SET TRANSACTION</code> to specify
concurrency levels on transactions. <span class="productname">PostgreSQL</span> supports that too;
see <a href="sql-set-transaction.html">SET TRANSACTION</a> for details.
</p>
<p> Except for <code class="literal">ACCESS SHARE</code>, <code class="literal">ACCESS EXCLUSIVE</code>,
and <code class="literal">SHARE UPDATE EXCLUSIVE</code> lock modes, the
<span class="productname">PostgreSQL</span> lock modes and the
<code class="command">LOCK TABLE</code> syntax are compatible with those
present in <span class="productname">Oracle</span>.
</p>
</div>
</div></body>
</html>
|