LOCK

Function

LOCK TABLE obtains a table-level lock.

When the lock for commands referencing a table is automatically acquired, GaussDB(DWS) always uses the lock mode with minimum constraints. 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
12
13
14
15
16
17
18
19
20
21
22
23
24
25
DROP TABLE IF EXISTS customer_address;
CREATE TABLE customer_address
(
    ca_address_sk       INTEGER                  NOT NULL   ,
    ca_address_id       CHARACTER(16)            NOT NULL   ,
    ca_street_number    CHARACTER(10)                       ,
    ca_street_name      CHARACTER varying(60)               ,
    ca_street_type      CHARACTER(15)                       ,
    ca_suite_number     CHARACTER(10)                    
)
DISTRIBUTE BY HASH (ca_address_sk)
PARTITION BY RANGE(ca_address_sk)
(
        PARTITION P1 VALUES LESS THAN(2450815),
        PARTITION P2 VALUES LESS THAN(2451179),
        PARTITION P3 VALUES LESS THAN(2451544),
        PARTITION P4 VALUES LESS THAN(MAXVALUE)
);
START TRANSACTION;

LOCK TABLE customer_address IN SHARE MODE;

SELECT ca_address_sk FROM customer_address WHERE ca_address_sk=5;

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
12
DROP TABLE IF EXISTS customer;
CREATE TABLE customer AS TABLE customer_address;

START TRANSACTION;

LOCK TABLE customer IN SHARE ROW EXCLUSIVE MODE;

DELETE FROM customer WHERE ca_address_sk IN(SELECT ca_address_sk FROM customer WHERE ca_address_sk < 6 );

DELETE FROM customer WHERE ca_address_sk = 7;

COMMIT;