1LOCK(7)                  PostgreSQL 10.7 Documentation                 LOCK(7)
2
3
4

NAME

6       LOCK - lock a table
7

SYNOPSIS

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

DESCRIPTION

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 acquiring locks automatically for commands that reference tables,
26       PostgreSQL always uses the least restrictive lock mode possible.  LOCK
27       TABLE provides for cases when you might need more restrictive locking.
28       For example, suppose an application runs a transaction at the READ
29       COMMITTED isolation level and needs to ensure that data in a table
30       remains stable for the duration of the transaction. To achieve this you
31       could obtain SHARE lock mode over the table before querying. This will
32       prevent concurrent data changes and ensure subsequent reads of the
33       table see a stable view of committed data, because SHARE lock mode
34       conflicts with the ROW EXCLUSIVE lock acquired by writers, and your
35       LOCK TABLE name IN SHARE MODE statement will wait until any concurrent
36       holders of ROW EXCLUSIVE mode locks commit or roll back. Thus, once you
37       obtain the lock, there are no uncommitted writes outstanding;
38       furthermore none can begin until you release the lock.
39
40       To achieve a similar effect when running a transaction at the
41       REPEATABLE READ or SERIALIZABLE isolation level, you have to execute
42       the LOCK TABLE statement before executing any SELECT or data
43       modification statement. A REPEATABLE READ or SERIALIZABLE transaction's
44       view of data will be frozen when its first SELECT or data modification
45       statement begins. A LOCK TABLE later in the transaction will still
46       prevent concurrent writes — but it won't ensure that what the
47       transaction reads corresponds to the latest committed values.
48
49       If a transaction of this sort is going to change the data in the table,
50       then it should use SHARE ROW EXCLUSIVE lock mode instead of SHARE mode.
51       This ensures that only one transaction of this type runs at a time.
52       Without this, a deadlock is possible: two transactions might both
53       acquire SHARE mode, and then be unable to also acquire ROW EXCLUSIVE
54       mode to actually perform their updates. (Note that a transaction's own
55       locks never conflict, so a transaction can acquire ROW EXCLUSIVE mode
56       when it holds SHARE mode — but not if anyone else holds SHARE mode.) To
57       avoid deadlocks, make sure all transactions acquire locks on the same
58       objects in the same order, and if multiple lock modes are involved for
59       a single object, then transactions should always acquire the most
60       restrictive mode first.
61
62       More information about the lock modes and locking strategies can be
63       found in Section 13.3.
64

PARAMETERS

66       name
67           The name (optionally schema-qualified) of an existing table to
68           lock. If ONLY is specified before the table name, only that table
69           is locked. If ONLY is not specified, the table and all its
70           descendant tables (if any) are locked. Optionally, * can be
71           specified after the table name to explicitly indicate that
72           descendant tables are included.
73
74           The command LOCK TABLE a, b; is equivalent to LOCK TABLE a; LOCK
75           TABLE b;. The tables are locked one-by-one in the order specified
76           in the LOCK TABLE command.
77
78       lockmode
79           The lock mode specifies which locks this lock conflicts with. Lock
80           modes are described in Section 13.3.
81
82           If no lock mode is specified, then ACCESS EXCLUSIVE, the most
83           restrictive mode, is used.
84
85       NOWAIT
86           Specifies that LOCK TABLE should not wait for any conflicting locks
87           to be released: if the specified lock(s) cannot be acquired
88           immediately without waiting, the transaction is aborted.
89

NOTES

91       LOCK TABLE ... IN ACCESS SHARE MODE requires SELECT privileges on the
92       target table.  LOCK TABLE ... IN ROW EXCLUSIVE MODE requires INSERT,
93       UPDATE, DELETE, or TRUNCATE privileges on the target table. All other
94       forms of LOCK require table-level UPDATE, DELETE, or TRUNCATE
95       privileges.
96
97       LOCK TABLE is useless outside a transaction block: the lock would
98       remain held only to the completion of the statement. Therefore
99       PostgreSQL reports an error if LOCK is used outside a transaction
100       block. Use BEGIN(7) and COMMIT(7) (or ROLLBACK(7)) to define a
101       transaction block.
102
103       LOCK TABLE only deals with table-level locks, and so the mode names
104       involving ROW are all misnomers. These mode names should generally be
105       read as indicating the intention of the user to acquire row-level locks
106       within the locked table. Also, ROW EXCLUSIVE mode is a shareable table
107       lock. Keep in mind that all the lock modes have identical semantics so
108       far as LOCK TABLE is concerned, differing only in the rules about which
109       modes conflict with which. For information on how to acquire an actual
110       row-level lock, see Section 13.3.2 and the The Locking Clause in the
111       SELECT reference documentation.
112

EXAMPLES

114       Obtain a SHARE lock on a primary key table when going to perform
115       inserts into a foreign key table:
116
117           BEGIN WORK;
118           LOCK TABLE films IN SHARE MODE;
119           SELECT id FROM films
120               WHERE name = 'Star Wars: Episode I - The Phantom Menace';
121           -- Do ROLLBACK if record was not returned
122           INSERT INTO films_user_comments VALUES
123               (_id_, 'GREAT! I was waiting for it for so long!');
124           COMMIT WORK;
125
126       Take a SHARE ROW EXCLUSIVE lock on a primary key table when going to
127       perform a delete operation:
128
129           BEGIN WORK;
130           LOCK TABLE films IN SHARE ROW EXCLUSIVE MODE;
131           DELETE FROM films_user_comments WHERE id IN
132               (SELECT id FROM films WHERE rating < 5);
133           DELETE FROM films WHERE rating < 5;
134           COMMIT WORK;
135

COMPATIBILITY

137       There is no LOCK TABLE in the SQL standard, which instead uses SET
138       TRANSACTION to specify concurrency levels on transactions.  PostgreSQL
139       supports that too; see SET TRANSACTION (SET_TRANSACTION(7)) for
140       details.
141
142       Except for ACCESS SHARE, ACCESS EXCLUSIVE, and SHARE UPDATE EXCLUSIVE
143       lock modes, the PostgreSQL lock modes and the LOCK TABLE syntax are
144       compatible with those present in Oracle.
145
146
147
148PostgreSQL 10.7                      2019                              LOCK(7)
Impressum