The code to unlink dropped relations in FinishPreparedTransaction() was
[PostgreSQL.git] / doc / src / sgml / ref / lock.sgml
blob814a831ef2d6df320a7336707a190881f31d8f3b
1 <!--
2 $PostgreSQL$
3 PostgreSQL documentation
4 -->
6 <refentry id="SQL-LOCK">
7 <refmeta>
8 <refentrytitle id="sql-lock-title">LOCK</refentrytitle>
9 <manvolnum>7</manvolnum>
10 <refmiscinfo>SQL - Language Statements</refmiscinfo>
11 </refmeta>
13 <refnamediv>
14 <refname>LOCK</refname>
15 <refpurpose>lock a table</refpurpose>
16 </refnamediv>
18 <indexterm zone="sql-lock">
19 <primary>LOCK</primary>
20 </indexterm>
22 <refsynopsisdiv>
23 <synopsis>
24 LOCK [ TABLE ] [ ONLY ] <replaceable class="PARAMETER">name</replaceable> [, ...] [ IN <replaceable class="PARAMETER">lockmode</replaceable> MODE ] [ NOWAIT ]
26 where <replaceable class="PARAMETER">lockmode</replaceable> is one of:
28 ACCESS SHARE | ROW SHARE | ROW EXCLUSIVE | SHARE UPDATE EXCLUSIVE
29 | SHARE | SHARE ROW EXCLUSIVE | EXCLUSIVE | ACCESS EXCLUSIVE
30 </synopsis>
31 </refsynopsisdiv>
33 <refsect1>
34 <title>Description</title>
36 <para>
37 <command>LOCK TABLE</command> obtains a table-level lock, waiting
38 if necessary for any conflicting locks to be released. If
39 <literal>NOWAIT</literal> is specified, <command>LOCK
40 TABLE</command> does not wait to acquire the desired lock: if it
41 cannot be acquired immediately, the command is aborted and an
42 error is emitted. Once obtained, the lock is held for the
43 remainder of the current transaction. (There is no <command>UNLOCK
44 TABLE</command> command; locks are always released at transaction
45 end.)
46 </para>
48 <para>
49 When acquiring locks automatically for commands that reference
50 tables, <productname>PostgreSQL</productname> always uses the least
51 restrictive lock mode possible. <command>LOCK TABLE</command>
52 provides for cases when you might need more restrictive locking.
53 For example, suppose an application runs a transaction at the
54 Read Committed isolation level and needs to ensure that data in a
55 table remains stable for the duration of the transaction. To
56 achieve this you could obtain <literal>SHARE</> lock mode over the
57 table before querying. This will prevent concurrent data changes
58 and ensure subsequent reads of the table see a stable view of
59 committed data, because <literal>SHARE</> lock mode conflicts with
60 the <literal>ROW EXCLUSIVE</> lock acquired by writers, and your
61 <command>LOCK TABLE <replaceable
62 class="PARAMETER">name</replaceable> IN SHARE MODE</command>
63 statement will wait until any concurrent holders of <literal>ROW
64 EXCLUSIVE</literal> mode locks commit or roll back. Thus, once you
65 obtain the lock, there are no uncommitted writes outstanding;
66 furthermore none can begin until you release the lock.
67 </para>
69 <para>
70 To achieve a similar effect when running a transaction at the Serializable
71 isolation level, you have to execute the <command>LOCK TABLE</> statement
72 before executing any <command>SELECT</> or data modification statement.
73 A serializable transaction's view of data will be frozen when its first
74 <command>SELECT</> or data modification statement begins. A <command>LOCK
75 TABLE</> later in the transaction will still prevent concurrent writes
76 &mdash; but it won't ensure that what the transaction reads corresponds to
77 the latest committed values.
78 </para>
80 <para>
81 If a transaction of this sort is going to change the data in the
82 table, then it should use <literal>SHARE ROW EXCLUSIVE</> lock mode
83 instead of <literal>SHARE</> mode. This ensures that only one
84 transaction of this type runs at a time. Without this, a deadlock
85 is possible: two transactions might both acquire <literal>SHARE</>
86 mode, and then be unable to also acquire <literal>ROW EXCLUSIVE</>
87 mode to actually perform their updates. (Note that a transaction's
88 own locks never conflict, so a transaction can acquire <literal>ROW
89 EXCLUSIVE</> mode when it holds <literal>SHARE</> mode &mdash; but not
90 if anyone else holds <literal>SHARE</> mode.) To avoid deadlocks,
91 make sure all transactions acquire locks on the same objects in the
92 same order, and if multiple lock modes are involved for a single
93 object, then transactions should always acquire the most
94 restrictive mode first.
95 </para>
97 <para>
98 More information about the lock modes and locking strategies can be
99 found in <xref linkend="explicit-locking">.
100 </para>
101 </refsect1>
103 <refsect1>
104 <title>Parameters</title>
106 <variablelist>
107 <varlistentry>
108 <term><replaceable class="PARAMETER">name</replaceable></term>
109 <listitem>
110 <para>
111 The name (optionally schema-qualified) of an existing table to
112 lock. If <literal>ONLY</> is specified, only that table is
113 locked. If <literal>ONLY</> is not specified, the table and all
114 its descendant tables (if any) are locked.
115 </para>
117 <para>
118 The command <literal>LOCK TABLE a, b;</> is equivalent to
119 <literal>LOCK TABLE a; LOCK TABLE b;</>. The tables are locked
120 one-by-one in the order specified in the <command>LOCK
121 TABLE</command> command.
122 </para>
123 </listitem>
124 </varlistentry>
126 <varlistentry>
127 <term><replaceable class="parameter">lockmode</replaceable></term>
128 <listitem>
129 <para>
130 The lock mode specifies which locks this lock conflicts with.
131 Lock modes are described in <xref linkend="explicit-locking">.
132 </para>
134 <para>
135 If no lock mode is specified, then <literal>ACCESS
136 EXCLUSIVE</literal>, the most restrictive mode, is used.
137 </para>
138 </listitem>
139 </varlistentry>
141 <varlistentry>
142 <term><literal>NOWAIT</literal></term>
143 <listitem>
144 <para>
145 Specifies that <command>LOCK TABLE</command> should not wait for
146 any conflicting locks to be released: if the specified lock(s)
147 cannot be acquired immediately without waiting, the transaction
148 is aborted.
149 </para>
150 </listitem>
151 </varlistentry>
152 </variablelist>
153 </refsect1>
155 <refsect1>
156 <title>Notes</title>
158 <para>
159 <literal>LOCK TABLE ... IN ACCESS SHARE MODE</> requires <literal>SELECT</>
160 privileges on the target table. All other forms of <command>LOCK</>
161 require at least one of <literal>UPDATE</>, <literal>DELETE</>, or
162 <literal>TRUNCATE</> privileges.
163 </para>
165 <para>
166 <command>LOCK TABLE</> is useless outside a transaction block: the lock
167 would remain held only to the completion of the statement. Therefore
168 <productname>PostgreSQL</productname> reports an error if <command>LOCK</>
169 is used outside a transaction block.
171 <xref linkend="sql-begin" endterm="sql-begin-title"> and
172 <xref linkend="sql-commit" endterm="sql-commit-title">
173 (or <xref linkend="sql-rollback" endterm="sql-rollback-title">)
174 to define a transaction block.
175 </para>
177 <para>
178 <command>LOCK TABLE</> only deals with table-level locks, and so
179 the mode names involving <literal>ROW</> are all misnomers. These
180 mode names should generally be read as indicating the intention of
181 the user to acquire row-level locks within the locked table. Also,
182 <literal>ROW EXCLUSIVE</> mode is a sharable table lock. Keep in
183 mind that all the lock modes have identical semantics so far as
184 <command>LOCK TABLE</> is concerned, differing only in the rules
185 about which modes conflict with which. For information on how to
186 acquire an actual row-level lock, see <xref linkend="locking-rows">
187 and the <xref linkend="sql-for-update-share"
188 endterm="sql-for-update-share-title"> in the <command>SELECT</command>
189 reference documentation.
190 </para>
191 </refsect1>
193 <refsect1>
194 <title>Examples</title>
196 <para>
197 Obtain a <literal>SHARE</> lock on a primary key table when going to perform
198 inserts into a foreign key table:
200 <programlisting>
201 BEGIN WORK;
202 LOCK TABLE films IN SHARE MODE;
203 SELECT id FROM films
204 WHERE name = 'Star Wars: Episode I - The Phantom Menace';
205 -- Do ROLLBACK if record was not returned
206 INSERT INTO films_user_comments VALUES
207 (_id_, 'GREAT! I was waiting for it for so long!');
208 COMMIT WORK;
209 </programlisting>
210 </para>
212 <para>
213 Take a <literal>SHARE ROW EXCLUSIVE</> lock on a primary key table when going to perform
214 a delete operation:
216 <programlisting>
217 BEGIN WORK;
218 LOCK TABLE films IN SHARE ROW EXCLUSIVE MODE;
219 DELETE FROM films_user_comments WHERE id IN
220 (SELECT id FROM films WHERE rating &lt; 5);
221 DELETE FROM films WHERE rating &lt; 5;
222 COMMIT WORK;
223 </programlisting>
224 </para>
225 </refsect1>
227 <refsect1>
228 <title>Compatibility</title>
230 <para>
231 There is no <command>LOCK TABLE</command> in the SQL standard,
232 which instead uses <command>SET TRANSACTION</command> to specify
233 concurrency levels on transactions. <productname>PostgreSQL</productname> supports that too;
234 see <xref linkend="SQL-SET-TRANSACTION"
235 endterm="SQL-SET-TRANSACTION-TITLE"> for details.
236 </para>
238 <para>
239 Except for <literal>ACCESS SHARE</>, <literal>ACCESS EXCLUSIVE</>,
240 and <literal>SHARE UPDATE EXCLUSIVE</> lock modes, the
241 <productname>PostgreSQL</productname> lock modes and the
242 <command>LOCK TABLE</command> syntax are compatible with those
243 present in <productname>Oracle</productname>.
244 </para>
245 </refsect1>
246 </refentry>