aboutsummaryrefslogtreecommitdiff
path: root/doc/src/sgml/ref/lock.sgml
blob: 50823f08743175a672c46dea4645b45b29d60fda (plain)
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
189
190
191
192
193
194
195
196
197
198
199
200
201
202
203
204
205
206
207
208
209
210
211
212
213
214
215
216
217
218
219
220
221
222
223
224
225
226
227
228
229
230
231
232
233
234
235
236
237
238
239
240
241
242
243
244
245
246
247
248
249
250
251
252
253
254
255
256
257
258
259
260
261
262
263
264
265
266
267
268
269
270
271
272
273
274
275
276
277
278
279
280
281
282
283
284
285
286
287
288
289
290
291
292
293
294
295
296
297
298
299
300
301
302
303
304
305
306
307
308
309
310
311
312
313
314
315
316
317
318
319
320
321
322
323
324
325
326
327
328
329
330
331
332
333
334
335
336
337
338
339
340
341
342
343
344
345
346
347
348
349
350
351
352
353
354
355
356
357
358
359
360
361
362
363
364
365
366
367
368
369
370
371
372
373
374
375
376
377
378
379
380
381
382
383
384
385
386
387
388
389
390
391
392
393
394
395
396
397
398
399
400
401
402
403
404
405
406
407
408
409
410
411
412
413
414
415
416
417
418
419
420
421
422
423
424
425
426
427
428
429
430
431
432
433
434
435
436
437
438
439
440
441
442
443
444
445
446
447
448
449
450
451
452
453
454
455
456
457
458
459
460
461
462
463
464
465
466
467
468
469
470
471
472
473
474
475
476
477
478
479
480
481
482
483
484
485
486
487
488
489
490
491
492
493
494
495
496
497
498
499
500
501
502
503
<!--
$Header: /cvsroot/pgsql/doc/src/sgml/ref/lock.sgml,v 1.30 2002/01/18 01:05:43 tgl Exp $
PostgreSQL documentation
-->

<refentry id="SQL-LOCK">
 <refmeta>
  <refentrytitle id="sql-lock-title">
   LOCK
  </refentrytitle>
  <refmiscinfo>SQL - Language Statements</refmiscinfo>
 </refmeta>
 <refnamediv>
  <refname>
   LOCK
  </refname>
  <refpurpose>
   explicitly lock a table
  </refpurpose>
 </refnamediv>
 <refsynopsisdiv>
  <refsynopsisdivinfo>
   <date>2001-07-09</date>
  </refsynopsisdivinfo>
  <synopsis>
LOCK [ TABLE ] <replaceable class="PARAMETER">name</replaceable> [, ...]
LOCK [ TABLE ] <replaceable class="PARAMETER">name</replaceable> [, ...] IN <replaceable class="PARAMETER">lockmode</replaceable> MODE

where <replaceable class="PARAMETER">lockmode</replaceable> is one of:

	ACCESS SHARE | ROW SHARE | ROW EXCLUSIVE | SHARE UPDATE EXCLUSIVE |
	SHARE | SHARE ROW EXCLUSIVE | EXCLUSIVE | ACCESS EXCLUSIVE
  </synopsis>

  <refsect2 id="R2-SQL-LOCK-1">
   <refsect2info>
    <date>1999-06-09</date>
   </refsect2info>

   <title>
    Inputs
   </title>
   <para>

    <variablelist>
     <varlistentry>
      <term><replaceable class="PARAMETER">name</replaceable></term>
      <listitem>
       <para>
	The name of an existing table to lock.
       </para>
      </listitem>
     </varlistentry>

     <varlistentry>
      <term>ACCESS SHARE MODE</term>
      <listitem>
       <note>
	<para>
	 This lock mode is acquired automatically over tables being queried.
	</para>
       </note>

       <para>
	This is the least restrictive lock mode.  It conflicts only with
	ACCESS EXCLUSIVE mode. It is used to protect a table from being
	modified by concurrent <command>ALTER TABLE</command>, 
	<command>DROP TABLE</command> and <command>VACUUM FULL</command>
	commands.
       </para>
      </listitem>
     </varlistentry>

     <varlistentry>
      <term>ROW SHARE MODE</term>
      <listitem>
       <note>
       <para>
	 Automatically acquired by <command>SELECT ... FOR UPDATE</command>.
	</para>
       </note>

       <para>
	Conflicts with EXCLUSIVE and ACCESS EXCLUSIVE lock modes.
       </para>
      </listitem>
     </varlistentry>

     <varlistentry>
      <term>ROW EXCLUSIVE MODE</term>
      <listitem>
       <note>
	<para>
	 Automatically acquired by <command>UPDATE</command>, 
	 <command>DELETE</command>, and <command>INSERT</command>
	 statements.
        </para>
       </note>

       <para>
	 Conflicts with SHARE, SHARE ROW EXCLUSIVE, EXCLUSIVE and
	 ACCESS EXCLUSIVE modes.
       </para>
      </listitem>
     </varlistentry>

     <varlistentry>
      <term>SHARE UPDATE EXCLUSIVE MODE</term>
      <listitem>
       <note>
       <para>
	 Automatically acquired by <command>VACUUM</command> (without
	 <option>FULL</option>).
       </para>
       </note>

       <para>
	Conflicts with SHARE UPDATE EXCLUSIVE, SHARE, SHARE ROW EXCLUSIVE,
	EXCLUSIVE and
	ACCESS EXCLUSIVE modes. This mode protects a table against
	concurrent schema changes and VACUUMs.
       </para>
      </listitem>
     </varlistentry>

     <varlistentry>
      <term>SHARE MODE</term>
      <listitem>
       <note>
       <para>
	 Automatically acquired by <command>CREATE INDEX</command>.
	 Share-locks the entire table.
       </para>
       </note>

       <para>
	Conflicts with ROW EXCLUSIVE, SHARE UPDATE EXCLUSIVE,
	SHARE ROW EXCLUSIVE, EXCLUSIVE and
	ACCESS EXCLUSIVE modes. This mode protects a table against
	concurrent data updates.
       </para>
      </listitem>
     </varlistentry>

     <varlistentry>
      <term>SHARE ROW EXCLUSIVE MODE</term>
      <listitem>
       <note>
       <para>
	This is like EXCLUSIVE MODE, but allows ROW SHARE locks
        by others.
       </para>
       </note>

       <para>
        Conflicts with ROW EXCLUSIVE, SHARE UPDATE EXCLUSIVE, SHARE,
	SHARE ROW EXCLUSIVE, EXCLUSIVE and ACCESS EXCLUSIVE modes.
       </para>
      </listitem>
     </varlistentry>

     <varlistentry>
      <term>EXCLUSIVE MODE</term>
      <listitem>

       <note>
       <para>
	This mode is yet more restrictive than SHARE ROW EXCLUSIVE.  
	It blocks all concurrent ROW SHARE/SELECT...FOR UPDATE queries.
       </para>
       </note>

       <para>
	Conflicts with ROW SHARE, ROW EXCLUSIVE, SHARE UPDATE EXCLUSIVE,
	SHARE, SHARE ROW EXCLUSIVE,
	EXCLUSIVE and ACCESS EXCLUSIVE modes.
	This mode allows only concurrent ACCESS SHARE, i.e., only reads
	from the table can proceed in parallel with a transaction holding
	this lock mode.
       </para>
      </listitem>
     </varlistentry>

     <varlistentry>
      <term>ACCESS EXCLUSIVE MODE</term>
      <listitem>
       <note>
	<para>
	 Automatically acquired by <command>ALTER TABLE</command>,
	 <command>DROP TABLE</command>, <command>VACUUM FULL</command>
	 statements.
	 This is the most restrictive lock mode which
	 protects a locked table from any concurrent operations.
	</para>
       </note>

       <note>
	<para>
	 This lock mode is also acquired by an unqualified
	 <command>LOCK TABLE</command> (i.e., the command without an explicit
	 lock mode option).
	</para>
       </note>

       <para>
	Conflicts with all lock modes.
       </para>
      </listitem>
     </varlistentry>
    </variablelist>
   </para>
  </refsect2>

  <refsect2 id="R2-SQL-LOCK-2">
   <refsect2info>
    <date>1998-09-24</date>
   </refsect2info>
   <title>
    Outputs
   </title>
   <para>
    
    <variablelist>
     <varlistentry>
      <term><computeroutput>
LOCK TABLE
       </computeroutput></term>
      <listitem>
       <para>
	The lock was successfully acquired.
       </para>
      </listitem>
     </varlistentry>

     <varlistentry>
      <term><computeroutput>
ERROR <replaceable class="PARAMETER">name</replaceable>: Table does not exist.
       </computeroutput></term>
      <listitem>
       <para>
	Message returned if <replaceable class="PARAMETER">name</replaceable>
	does not exist.
       </para>
      </listitem>
     </varlistentry>
    </variablelist>
   </para>
  </refsect2>
 </refsynopsisdiv>

 <refsect1 id="R1-SQL-LOCK-1">
  <refsect1info>
   <date>1998-09-24</date>
  </refsect1info>
  <title>
   Description
  </title>

  <para>
   <command>LOCK TABLE</command> controls concurrent access to a table
   for the duration of a transaction.
   <productname>PostgreSQL</productname> always uses the least restrictive
   lock mode whenever possible. <command>LOCK TABLE</command> 
   provides for cases when you might need more restrictive locking.
  </para>

  <para>
   <acronym>RDBMS</acronym> locking uses the following terminology:

   <variablelist>
    <varlistentry>
     <term>EXCLUSIVE</term>
     <listitem>
      <para>
       An exclusive lock prevents other locks of the same type from being
       granted.  (Note: ROW EXCLUSIVE mode does not follow this naming
       convention perfectly, since it is shared at the level of the table;
       it is exclusive only with respect to specific rows that are being
       updated.)
      </para>
     </listitem>
    </varlistentry>

    <varlistentry>
     <term>SHARE</term>
     <listitem>
      <para>
      A shared lock allows others to also hold the same type of lock,
      but prevents the corresponding EXCLUSIVE lock from being granted.
      </para>
     </listitem>
    </varlistentry>

    <varlistentry>
     <term>ACCESS</term>
     <listitem>
      <para>
       Locks table schema.
      </para>
     </listitem>
    </varlistentry>

    <varlistentry>
     <term>ROW</term>
     <listitem>
      <para>
       Locks individual rows.
      </para>
     </listitem>
    </varlistentry>
   </variablelist>
  </para>

  <para>
   For example, suppose an application runs a transaction at READ COMMITTED
   isolation level and needs to ensure the existence of data in a table for
   the duration of the
   transaction. To achieve this you could obtain SHARE lock mode over the
   table before querying. This will prevent concurrent data changes 
   and ensure further read operations over the table see data in their 
   actual current state, because SHARE lock mode conflicts with any ROW
   EXCLUSIVE lock acquired by writers, and your
   <command>LOCK TABLE <replaceable class="PARAMETER">name</replaceable> IN SHARE MODE</command>
   statement will wait until any concurrent write operations commit or
   rollback. Thus, once you obtain the lock, there are no uncommitted
   writes outstanding.

   <note>
    <para>
     To read data in their actual current state when running a transaction
     at the SERIALIZABLE isolation level, you have to execute the LOCK TABLE
     statement before executing any DML statement.  A serializable
     transaction's view of data will be frozen when its first DML statement
     begins.
    </para>
   </note>
  </para>
  
  <para>
   In addition to the requirements above, if a transaction is going to
   change data in a table, then SHARE ROW EXCLUSIVE lock mode should
   be acquired to prevent deadlock conditions when two concurrent
   transactions attempt to lock the table in SHARE mode and then
   try to change data in this table, both (implicitly) acquiring 
   ROW EXCLUSIVE lock mode that conflicts with a concurrent SHARE lock.
  </para>
  
  <para>
   To continue with the deadlock (when two transactions wait for one another)
   issue raised above, you should follow two general rules to prevent 
   deadlock conditions:
  </para>

  <itemizedlist>  
   <listitem>
    <para>
     Transactions have to acquire locks on the same objects in the same order.
    </para>
   
    <para>
     For example, if one application updates row R1 and than updates 
     row R2 (in the same transaction) then the second application shouldn't 
     update row R2 if it's going to update row R1 later (in a single transaction). 
     Instead, it should update rows R1 and R2 in the same order as the first 
     application.
    </para>
   </listitem>

   <listitem>
    <para>
     Transactions should acquire two conflicting lock modes only if
     one of them is self-conflicting (i.e., may be held by only one
     transaction at a time). If multiple lock modes are involved,
     then transactions should always acquire the  most restrictive mode first.
    </para>
   
    <para>
     An example for this rule was given previously when discussing the 
     use of SHARE ROW EXCLUSIVE mode rather than SHARE mode.
    </para>

   </listitem>
  </itemizedlist>

  <note>
   <para>
    <productname>PostgreSQL</productname> does detect deadlocks and will
    rollback at least one waiting transaction to resolve the deadlock. 
   </para>
  </note>

  <para>
   When locking multiple tables, the command LOCK a, b; is equivalent to LOCK
   a; LOCK b;. The tables are locked one-by-one in the order specified in the
   <command>LOCK</command> command.
  </para>

  <refsect2 id="R2-SQL-LOCK-3">
   <refsect2info>
    <date>1999-06-08</date>
   </refsect2info>
   <title>
    Notes
   </title>

   <para>
    <literal>LOCK ... IN ACCESS SHARE MODE</> requires <literal>SELECT</>
    privileges on the target table.  All other forms of <command>LOCK</>
    require <literal>UPDATE</> and/or <literal>DELETE</> privileges.
   </para>

   <para>
    <command>LOCK</command> is useful only inside a transaction block
    (<command>BEGIN</>...<command>COMMIT</>), since the lock is dropped
    as soon as the transaction ends.  A <command>LOCK</> command appearing
    outside any transaction block forms a self-contained transaction, so the
    lock will be dropped as soon as it is obtained.
   </para>

  </refsect2>
 </refsect1>
  
 <refsect1 id="R1-SQL-LOCK-2">
  <title>
   Usage
  </title>

  <para>
   Illustrate a SHARE lock on a primary key table when going to perform
   inserts into a foreign key table:

  <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;
   </programlisting>
  </para>

  <para>
   Take a SHARE ROW EXCLUSIVE lock on a primary key table when going to perform
   a delete operation:

   <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;
   </programlisting>
  </para>
 </refsect1>

 <refsect1 id="R1-SQL-LOCK-3">
  <title>
   Compatibility
  </title>
	  
  <refsect2 id="R2-SQL-LOCK-4">
   <refsect2info>
    <date>1998-09-24</date>
   </refsect2info>
   <title>
    SQL92
   </title>
   <para>
    There is no <command>LOCK TABLE</command> in <acronym>SQL92</acronym>,
    which instead uses <command>SET TRANSACTION</command> to specify
    concurrency levels on transactions.  We support that too; see
    <xref linkend="SQL-SET-TRANSACTION" endterm="SQL-SET-TRANSACTION-TITLE"> for details.
   </para>

   <para>
    Except for ACCESS SHARE, ACCESS EXCLUSIVE, and SHARE UPDATE EXCLUSIVE lock
    modes, the <productname>PostgreSQL</productname> lock modes and the
    <command>LOCK TABLE</command> syntax are compatible with those
    present in <productname>Oracle</productname>(TM).
   </para>
  </refsect2>
 </refsect1>
</refentry>

<!-- Keep this comment at the end of the file
Local variables:
mode: sgml
sgml-omittag:nil
sgml-shorttag:t
sgml-minimize-attributes:nil
sgml-always-quote-attributes:t
sgml-indent-step:1
sgml-indent-data:t
sgml-parent-document:nil
sgml-default-dtd-file:"../reference.ced"
sgml-exposed-tags:nil
sgml-local-catalogs:"/usr/lib/sgml/catalog"
sgml-local-ecat-files:nil
End:
-->