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>LOCK</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="sql-load.html" title="LOAD" /><link rel="next" href="sql-merge.html" title="MERGE" /></head><body id="docContent" class="container-fluid col-10"><div class="navheader"><table width="100%" summary="Navigation header"><tr><th colspan="5" align="center">LOCK</th></tr><tr><td width="10%" align="left"><a accesskey="p" href="sql-load.html" title="LOAD">Prev</a> </td><td width="10%" align="left"><a accesskey="u" href="sql-commands.html" title="SQL Commands">Up</a></td><th width="60%" align="center">SQL Commands</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="sql-merge.html" title="MERGE">Next</a></td></tr></table><hr /></div><div class="refentry" id="SQL-LOCK"><div class="titlepage"></div><a id="id-1.9.3.155.1" class="indexterm"></a><div class="refnamediv"><h2><span class="refentrytitle">LOCK</span></h2><p>LOCK — lock a table</p></div><div class="refsynopsisdiv"><h2>Synopsis</h2><pre class="synopsis">
3 LOCK [ TABLE ] [ ONLY ] <em class="replaceable"><code>name</code></em> [ * ] [, ...] [ IN <em class="replaceable"><code>lockmode</code></em> MODE ] [ NOWAIT ]
5 <span class="phrase">where <em class="replaceable"><code>lockmode</code></em> is one of:</span>
7 ACCESS SHARE | ROW SHARE | ROW EXCLUSIVE | SHARE UPDATE EXCLUSIVE
8 | SHARE | SHARE ROW EXCLUSIVE | EXCLUSIVE | ACCESS EXCLUSIVE
9 </pre></div><div class="refsect1" id="id-1.9.3.155.5"><h2>Description</h2><p>
10 <code class="command">LOCK TABLE</code> obtains a table-level lock, waiting
11 if necessary for any conflicting locks to be released. If
12 <code class="literal">NOWAIT</code> is specified, <code class="command">LOCK
13 TABLE</code> does not wait to acquire the desired lock: if it
14 cannot be acquired immediately, the command is aborted and an
15 error is emitted. Once obtained, the lock is held for the
16 remainder of the current transaction. (There is no <code class="command">UNLOCK
17 TABLE</code> command; locks are always released at transaction
20 When a view is locked, all relations appearing in the view definition
21 query are also locked recursively with the same lock mode.
23 When acquiring locks automatically for commands that reference
24 tables, <span class="productname">PostgreSQL</span> always uses the least
25 restrictive lock mode possible. <code class="command">LOCK TABLE</code>
26 provides for cases when you might need more restrictive locking.
27 For example, suppose an application runs a transaction at the
28 <code class="literal">READ COMMITTED</code> isolation level and needs to ensure that
29 data in a table remains stable for the duration of the transaction.
30 To achieve this you could obtain <code class="literal">SHARE</code> lock mode over the
31 table before querying. This will prevent concurrent data changes
32 and ensure subsequent reads of the table see a stable view of
33 committed data, because <code class="literal">SHARE</code> lock mode conflicts with
34 the <code class="literal">ROW EXCLUSIVE</code> lock acquired by writers, and your
35 <code class="command">LOCK TABLE <em class="replaceable"><code>name</code></em> IN SHARE MODE</code>
36 statement will wait until any concurrent holders of <code class="literal">ROW
37 EXCLUSIVE</code> mode locks commit or roll back. Thus, once you
38 obtain the lock, there are no uncommitted writes outstanding;
39 furthermore none can begin until you release the lock.
41 To achieve a similar effect when running a transaction at the
42 <code class="literal">REPEATABLE READ</code> or <code class="literal">SERIALIZABLE</code>
43 isolation level, you have to execute the <code class="command">LOCK TABLE</code> statement
44 before executing any <code class="command">SELECT</code> or data modification statement.
45 A <code class="literal">REPEATABLE READ</code> or <code class="literal">SERIALIZABLE</code> transaction's
46 view of data will be frozen when its first
47 <code class="command">SELECT</code> or data modification statement begins. A <code class="command">LOCK
48 TABLE</code> later in the transaction will still prevent concurrent writes
49 — but it won't ensure that what the transaction reads corresponds to
50 the latest committed values.
52 If a transaction of this sort is going to change the data in the
53 table, then it should use <code class="literal">SHARE ROW EXCLUSIVE</code> lock mode
54 instead of <code class="literal">SHARE</code> mode. This ensures that only one
55 transaction of this type runs at a time. Without this, a deadlock
56 is possible: two transactions might both acquire <code class="literal">SHARE</code>
57 mode, and then be unable to also acquire <code class="literal">ROW EXCLUSIVE</code>
58 mode to actually perform their updates. (Note that a transaction's
59 own locks never conflict, so a transaction can acquire <code class="literal">ROW
60 EXCLUSIVE</code> mode when it holds <code class="literal">SHARE</code> mode — but not
61 if anyone else holds <code class="literal">SHARE</code> mode.) To avoid deadlocks,
62 make sure all transactions acquire locks on the same objects in the
63 same order, and if multiple lock modes are involved for a single
64 object, then transactions should always acquire the most
65 restrictive mode first.
67 More information about the lock modes and locking strategies can be
68 found in <a class="xref" href="explicit-locking.html" title="13.3. Explicit Locking">Section 13.3</a>.
69 </p></div><div class="refsect1" id="id-1.9.3.155.6"><h2>Parameters</h2><div class="variablelist"><dl class="variablelist"><dt><span class="term"><em class="replaceable"><code>name</code></em></span></dt><dd><p>
70 The name (optionally schema-qualified) of an existing table to
71 lock. If <code class="literal">ONLY</code> is specified before the table name, only that
72 table is locked. If <code class="literal">ONLY</code> is not specified, the table and all
73 its descendant tables (if any) are locked. Optionally, <code class="literal">*</code>
74 can be specified after the table name to explicitly indicate that
75 descendant tables are included.
77 The command <code class="literal">LOCK TABLE a, b;</code> is equivalent to
78 <code class="literal">LOCK TABLE a; LOCK TABLE b;</code>. The tables are locked
79 one-by-one in the order specified in the <code class="command">LOCK
81 </p></dd><dt><span class="term"><em class="replaceable"><code>lockmode</code></em></span></dt><dd><p>
82 The lock mode specifies which locks this lock conflicts with.
83 Lock modes are described in <a class="xref" href="explicit-locking.html" title="13.3. Explicit Locking">Section 13.3</a>.
85 If no lock mode is specified, then <code class="literal">ACCESS
86 EXCLUSIVE</code>, the most restrictive mode, is used.
87 </p></dd><dt><span class="term"><code class="literal">NOWAIT</code></span></dt><dd><p>
88 Specifies that <code class="command">LOCK TABLE</code> should not wait for
89 any conflicting locks to be released: if the specified lock(s)
90 cannot be acquired immediately without waiting, the transaction
92 </p></dd></dl></div></div><div class="refsect1" id="id-1.9.3.155.7"><h2>Notes</h2><p>
93 To lock a table, the user must have the right privilege for the specified
94 <em class="replaceable"><code>lockmode</code></em>.
95 If the user has <code class="literal">MAINTAIN</code>,
96 <code class="literal">UPDATE</code>, <code class="literal">DELETE</code>, or
97 <code class="literal">TRUNCATE</code> privileges on the table, any <em class="replaceable"><code>lockmode</code></em> is permitted. If the user has
98 <code class="literal">INSERT</code> privileges on the table, <code class="literal">ROW EXCLUSIVE
99 MODE</code> (or a less-conflicting mode as described in <a class="xref" href="explicit-locking.html" title="13.3. Explicit Locking">Section 13.3</a>) is permitted. If a user has
100 <code class="literal">SELECT</code> privileges on the table, <code class="literal">ACCESS SHARE
101 MODE</code> is permitted.
103 The user performing the lock on the view must have the corresponding
104 privilege on the view. In addition, by default, the view's owner must
105 have the relevant privileges on the underlying base relations, whereas the
106 user performing the lock does not need any permissions on the underlying
107 base relations. However, if the view has
108 <code class="literal">security_invoker</code> set to <code class="literal">true</code>
109 (see <a class="link" href="sql-createview.html" title="CREATE VIEW"><code class="command">CREATE VIEW</code></a>),
110 the user performing the lock, rather than the view owner, must have the
111 relevant privileges on the underlying base relations.
113 <code class="command">LOCK TABLE</code> is useless outside a transaction block: the lock
114 would remain held only to the completion of the statement. Therefore
115 <span class="productname">PostgreSQL</span> reports an error if <code class="command">LOCK</code>
116 is used outside a transaction block.
118 <a class="link" href="sql-begin.html" title="BEGIN"><code class="command">BEGIN</code></a> and
119 <a class="link" href="sql-commit.html" title="COMMIT"><code class="command">COMMIT</code></a>
120 (or <a class="link" href="sql-rollback.html" title="ROLLBACK"><code class="command">ROLLBACK</code></a>)
121 to define a transaction block.
123 <code class="command">LOCK TABLE</code> only deals with table-level locks, and so
124 the mode names involving <code class="literal">ROW</code> are all misnomers. These
125 mode names should generally be read as indicating the intention of
126 the user to acquire row-level locks within the locked table. Also,
127 <code class="literal">ROW EXCLUSIVE</code> mode is a shareable table lock. Keep in
128 mind that all the lock modes have identical semantics so far as
129 <code class="command">LOCK TABLE</code> is concerned, differing only in the rules
130 about which modes conflict with which. For information on how to
131 acquire an actual row-level lock, see <a class="xref" href="explicit-locking.html#LOCKING-ROWS" title="13.3.2. Row-Level Locks">Section 13.3.2</a>
132 and <a class="xref" href="sql-select.html#SQL-FOR-UPDATE-SHARE" title="The Locking Clause">The Locking Clause</a>
133 in the <a class="xref" href="sql-select.html" title="SELECT"><span class="refentrytitle">SELECT</span></a> documentation.
134 </p></div><div class="refsect1" id="id-1.9.3.155.8"><h2>Examples</h2><p>
135 Obtain a <code class="literal">SHARE</code> lock on a primary key table when going to perform
136 inserts into a foreign key table:
138 </p><pre class="programlisting">
140 LOCK TABLE films IN SHARE MODE;
142 WHERE name = 'Star Wars: Episode I - The Phantom Menace';
143 -- Do ROLLBACK if record was not returned
144 INSERT INTO films_user_comments VALUES
145 (_id_, 'GREAT! I was waiting for it for so long!');
149 Take a <code class="literal">SHARE ROW EXCLUSIVE</code> lock on a primary key table when going to perform
152 </p><pre class="programlisting">
154 LOCK TABLE films IN SHARE ROW EXCLUSIVE MODE;
155 DELETE FROM films_user_comments WHERE id IN
156 (SELECT id FROM films WHERE rating < 5);
157 DELETE FROM films WHERE rating < 5;
159 </pre></div><div class="refsect1" id="id-1.9.3.155.9"><h2>Compatibility</h2><p>
160 There is no <code class="command">LOCK TABLE</code> in the SQL standard,
161 which instead uses <code class="command">SET TRANSACTION</code> to specify
162 concurrency levels on transactions. <span class="productname">PostgreSQL</span> supports that too;
163 see <a class="xref" href="sql-set-transaction.html" title="SET TRANSACTION"><span class="refentrytitle">SET TRANSACTION</span></a> for details.
165 Except for <code class="literal">ACCESS SHARE</code>, <code class="literal">ACCESS EXCLUSIVE</code>,
166 and <code class="literal">SHARE UPDATE EXCLUSIVE</code> lock modes, the
167 <span class="productname">PostgreSQL</span> lock modes and the
168 <code class="command">LOCK TABLE</code> syntax are compatible with those
169 present in <span class="productname">Oracle</span>.
170 </p></div></div><div class="navfooter"><hr /><table width="100%" summary="Navigation footer"><tr><td width="40%" align="left"><a accesskey="p" href="sql-load.html" title="LOAD">Prev</a> </td><td width="20%" align="center"><a accesskey="u" href="sql-commands.html" title="SQL Commands">Up</a></td><td width="40%" align="right"> <a accesskey="n" href="sql-merge.html" title="MERGE">Next</a></td></tr><tr><td width="40%" align="left" valign="top">LOAD </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"> MERGE</td></tr></table></div></body></html>