LOCK

Function

LOCK TABLE obtains a table-level lock.

GaussDB(DWS) always tries to select the lock mode with minimum constraints when automatically requesting a lock for a command referenced by a table. Use LOCK if users need a more strict lock mode. For example, suppose an application runs a transaction at the Read Committed isolation level and needs to ensure that data in a table remains stable in the duration of the transaction. To achieve this, you could obtain SHARE lock mode over the table before the query. This will prevent concurrent data changes and ensure subsequent reads of the table see a stable view of committed data. It is because the SHARE lock mode conflicts with the ROW EXCLUSIVE lock acquired by writers, and your LOCK TABLE name IN SHARE MODE statement will wait until any concurrent holders of ROW EXCLUSIVE mode locks commit or roll back. Therefore, once you obtain the lock, there are no uncommitted writes outstanding; furthermore none can begin until you release the lock.

Precautions

Syntax

1
2
3
LOCK [ TABLE ] {[ ONLY ] name [, ...]| {name [ * ]} [, ...]}
    [ IN {ACCESS SHARE | ROW SHARE | ROW EXCLUSIVE | SHARE UPDATE EXCLUSIVE | SHARE | SHARE ROW EXCLUSIVE | EXCLUSIVE | ACCESS EXCLUSIVE} MODE ]
    [ NOWAIT ];

Parameter Description

Table 1 Lock mode conflicts

Requested Lock Mode/Current Lock Mode

ACCESS SHARE

ROW SHARE

ROW EXCLUSIVE

SHARE UPDATE EXCLUSIVE

SHARE

SHARE ROW EXCLUSIVE

EXCLUSIVE

ACCESS EXCLUSIVE

ACCESS SHARE

-

-

-

-

-

-

-

X

ROW SHARE

-

-

-

-

-

-

X

X

ROW EXCLUSIVE

-

-

-

-

X

X

X

X

SHARE UPDATE EXCLUSIVE

-

-

-

X

X

X

X

X

SHARE

-

-

X

X

-

X

X

X

SHARE ROW EXCLUSIVE

-

-

X

X

X

X

X

X

EXCLUSIVE

-

X

X

X

X

X

X

X

ACCESS EXCLUSIVE

X

X

X

X

X

X

X

X

LOCK parameters are as follows:

Examples

Obtain a SHARE lock on a primary key table when going to perform inserts into a foreign key table.

 1
 2
 3
 4
 5
 6
 7
 8
 9
10
11
START TRANSACTION;

LOCK TABLE tpcds.reason IN SHARE MODE;

SELECT r_reason_desc FROM tpcds.reason WHERE r_reason_sk=5;
r_reason_desc
-----------
 Parts missing
(1 row)

COMMIT;

Obtain a SHARE ROW EXCLUSIVE lock on a primary key table when going to perform a delete operation.

 1
 2
 3
 4
 5
 6
 7
 8
 9
10
11
CREATE TABLE tpcds.reason_t1 AS TABLE tpcds.reason;

START TRANSACTION;

LOCK TABLE tpcds.reason_t1 IN SHARE ROW EXCLUSIVE MODE;

DELETE FROM tpcds.reason_t1 WHERE r_reason_desc IN(SELECT r_reason_desc FROM tpcds.reason_t1 WHERE r_reason_sk < 6 );

DELETE FROM tpcds.reason_t1 WHERE r_reason_sk = 7;

COMMIT;

Delete the tpcds.reason_t1 table.

1
DROP TABLE tpcds.reason_t1;