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