1LOCK() SQL Commands LOCK()
2
3
4
6 LOCK - lock a table
7
8
10 LOCK [ TABLE ] name [, ...] [ IN lockmode MODE ] [ NOWAIT ]
11
12 where lockmode is one of:
13
14 ACCESS SHARE | ROW SHARE | ROW EXCLUSIVE | SHARE UPDATE EXCLUSIVE
15 | SHARE | SHARE ROW EXCLUSIVE | EXCLUSIVE | ACCESS EXCLUSIVE
16
17
19 LOCK TABLE obtains a table-level lock, waiting if necessary for any
20 conflicting locks to be released. If NOWAIT is specified, LOCK TABLE
21 does not wait to acquire the desired lock: if it cannot be acquired
22 immediately, the command is aborted and an error is emitted. Once
23 obtained, the lock is held for the remainder of the current transac‐
24 tion. (There is no UNLOCK TABLE command; locks are always released at
25 transaction end.)
26
27 When acquiring locks automatically for commands that reference tables,
28 PostgreSQL always uses the least restrictive lock mode possible. LOCK
29 TABLE provides for cases when you might need more restrictive locking.
30 For example, suppose an application runs a transaction at the Read Com‐
31 mitted isolation level and needs to ensure that data in a table remains
32 stable for the duration of the transaction. To achieve this you could
33 obtain SHARE lock mode over the table before querying. This will pre‐
34 vent concurrent data changes and ensure subsequent reads of the table
35 see a stable view of committed data, because SHARE lock mode conflicts
36 with the ROW EXCLUSIVE lock acquired by writers, and your LOCK TABLE
37 name IN SHARE MODE statement will wait until any concurrent holders of
38 ROW EXCLUSIVE mode locks commit or roll back. Thus, once you obtain the
39 lock, there are no uncommitted writes outstanding; furthermore none can
40 begin until you release the lock.
41
42 To achieve a similar effect when running a transaction at the Serializ‐
43 able isolation level, you have to execute the LOCK TABLE statement
44 before executing any SELECT or data modification statement. A serial‐
45 izable transaction's view of data will be frozen when its first SELECT
46 or data modification statement begins. A LOCK TABLE later in the trans‐
47 action will still prevent concurrent writes — but it won't ensure that
48 what the transaction reads corresponds to the latest committed values.
49
50 If a transaction of this sort is going to change the data in the table,
51 then it should use SHARE ROW EXCLUSIVE lock mode instead of SHARE mode.
52 This ensures that only one transaction of this type runs at a time.
53 Without this, a deadlock is possible: two transactions might both
54 acquire SHARE mode, and then be unable to also acquire ROW EXCLUSIVE
55 mode to actually perform their updates. (Note that a transaction's own
56 locks never conflict, so a transaction can acquire ROW EXCLUSIVE mode
57 when it holds SHARE mode — but not if anyone else holds SHARE mode.) To
58 avoid deadlocks, make sure all transactions acquire locks on the same
59 objects in the same order, and if multiple lock modes are involved for
60 a single object, then transactions should always acquire the most
61 restrictive mode first.
62
63 More information about the lock modes and locking strategies can be
64 found in in the documentation.
65
67 name The name (optionally schema-qualified) of an existing table to
68 lock.
69
70 The command LOCK TABLE a, b; is equivalent to LOCK TABLE a; LOCK
71 TABLE b;. The tables are locked one-by-one in the order speci‐
72 fied in the LOCK TABLE command.
73
74 lockmode
75 The lock mode specifies which locks this lock conflicts with.
76 Lock modes are described in in the documentation.
77
78 If no lock mode is specified, then ACCESS EXCLUSIVE, the most
79 restrictive mode, is used.
80
81 NOWAIT Specifies that LOCK TABLE should not wait for any conflicting
82 locks to be released: if the specified lock(s) cannot be
83 acquired immediately without waiting, the transaction is
84 aborted.
85
87 LOCK TABLE ... IN ACCESS SHARE MODE requires SELECT privileges on the
88 target table. All other forms of LOCK require UPDATE and/or DELETE
89 privileges.
90
91 LOCK TABLE is useful only inside a transaction block (BEGIN/COMMIT
92 pair), since the lock is dropped as soon as the transaction ends. A
93 LOCK TABLE command appearing outside any transaction block forms a
94 self-contained transaction, so the lock will be dropped as soon as it
95 is obtained.
96
97 LOCK TABLE only deals with table-level locks, and so the mode names
98 involving ROW are all misnomers. These mode names should generally be
99 read as indicating the intention of the user to acquire row-level locks
100 within the locked table. Also, ROW EXCLUSIVE mode is a sharable table
101 lock. Keep in mind that all the lock modes have identical semantics so
102 far as LOCK TABLE is concerned, differing only in the rules about which
103 modes conflict with which. For information on how to acquire an actual
104 row-level lock, see in the documentation and the FOR UPDATE/FOR SHARE
105 Clause [select(7)] in the SELECT reference documentation.
106
108 Obtain a SHARE lock on a primary key table when going to perform
109 inserts into a foreign key table:
110
111 BEGIN WORK;
112 LOCK TABLE films IN SHARE MODE;
113 SELECT id FROM films
114 WHERE name = 'Star Wars: Episode I - The Phantom Menace';
115 -- Do ROLLBACK if record was not returned
116 INSERT INTO films_user_comments VALUES
117 (_id_, 'GREAT! I was waiting for it for so long!');
118 COMMIT WORK;
119
120
121 Take a SHARE ROW EXCLUSIVE lock on a primary key table when going to
122 perform a delete operation:
123
124 BEGIN WORK;
125 LOCK TABLE films IN SHARE ROW EXCLUSIVE MODE;
126 DELETE FROM films_user_comments WHERE id IN
127 (SELECT id FROM films WHERE rating < 5);
128 DELETE FROM films WHERE rating < 5;
129 COMMIT WORK;
130
131
133 There is no LOCK TABLE in the SQL standard, which instead uses SET
134 TRANSACTION to specify concurrency levels on transactions. PostgreSQL
135 supports that too; see SET TRANSACTION [set_transaction(7)] for
136 details.
137
138 Except for ACCESS SHARE, ACCESS EXCLUSIVE, and SHARE UPDATE EXCLUSIVE
139 lock modes, the PostgreSQL lock modes and the LOCK TABLE syntax are
140 compatible with those present in Oracle.
141
142
143
144SQL - Language Statements 2008-06-08 LOCK()