Advisory Lock Functions
Advisory lock functions manage advisory locks.
- pg_advisory_lock(key bigint)
Description: Obtains an exclusive session-level advisory lock.
Return type: void
Note: pg_advisory_lock locks resources defined by an application. The resources can be identified using a 64-bit or two nonoverlapped 32-bit key values. If another session locks the resources, the function blocks the resources until they can be used. The lock is exclusive. Multiple locking requests are pushed into the stack. Therefore, if the same resource is locked three times, it must be unlocked three times so that it is released to another session.
- pg_advisory_lock(key1 int, key2 int)
Description: Obtains an exclusive session-level advisory lock.
Return type: void
Note: Only users with the SYSADMIN permission can add session-level exclusive advisory locks to the key-value pair (65535, 65535).
- pg_advisory_lock(lock_id int4, lock_id int4, datebase_name Name)
Description: Obtains the exclusive advisory lock of a specified database by inputting the lock ID and database name.
Return type: void
- pg_advisory_lock_shared(key bigint)
Description: Obtains a shared session-level advisory lock.
Return type: void
- pg_advisory_lock_shared(key1 int, key2 int)
Description: Obtains a shared session-level advisory lock.
Return type: void
Note: pg_advisory_lock_shared works in the same way as pg_advisory_lock, except that pg_advisory_lock_shared obtains an advisory lock shared with other sessions requesting the lock, while pg_advisory_lock obtains an exclusive advisory lock.
- pg_advisory_unlock(key bigint)
Description: Releases an exclusive session-level advisory lock.
Return type: Boolean
- pg_advisory_unlock(key1 int, key2 int)
Description: Releases an exclusive session-level advisory lock.
Return type: Boolean
Note: pg_advisory_unlock releases the obtained exclusive advisory lock. If the release is successful, the function returns true. If the lock was not held, it will return false. In addition, an SQL warning will be reported by the server.
- pg_advisory_unlock(lock_id int4, lock_id int4, datebase_name Name)
Description: Releases an exclusive advisory lock of a specified database by inputting the lock ID and database name.
Return type: Boolean
Note: If the release is successful, true is returned. If no lock is held, false is returned.
- pg_advisory_unlock_shared(key bigint)
Description: Releases a shared session-level advisory lock.
Return type: Boolean
- pg_advisory_unlock_shared(key1 int, key2 int)
Description: Releases a shared session-level advisory lock.
Return type: Boolean
Note: pg_advisory_unlock_shared works in the same way as pg_advisory_unlock, except it releases a shared session-level advisory lock.
- pg_advisory_unlock_all()
Description: Releases all advisory locks owned by the current session.
Return type: void
Note: pg_advisory_unlock_all releases all advisory locks owned by the current session. The function is implicitly called when the session ends even if the client is abnormally disconnected.
- pg_advisory_xact_lock(key bigint)
Description: Obtains an exclusive transaction-level advisory lock.
Return type: void
- pg_advisory_xact_lock(key1 int, key2 int)
Description: Obtains an exclusive transaction-level advisory lock.
Return type: void
Note: pg_advisory_xact_lock works in the same way as pg_advisory_lock, except that the lock is automatically released at the end of the current transaction and cannot be released explicitly. Only users with the SYSADMIN permission can add transaction-level exclusive advisory locks to the key-value pair (65535, 65535).
- pg_advisory_xact_lock_shared(key bigint)
Description: Obtains a shared transaction-level advisory lock.
Return type: void
- pg_advisory_xact_lock_shared(key1 int, key2 int)
Description: Obtains a shared transaction-level advisory lock.
Return type: void
Note: pg_advisory_xact_lock_shared works in the same way as pg_advisory_lock_shared, except the lock is automatically released at the end of the current transaction and cannot be released explicitly.
- pg_try_advisory_lock(key bigint)
Description: Obtains an exclusive session-level advisory lock if available.
Return type: Boolean
Note: pg_try_advisory_lock works in the same way as pg_advisory_lock, except pg_try_advisory_lock does not block the resource until the resource is released. It either immediately obtains the lock and returns true or returns false, which indicates the lock cannot be performed currently.
- pg_try_advisory_lock(key1 int, key2 int)
Description: Obtains an exclusive session-level advisory lock if available.
Return type: Boolean
Note: Only users with the SYSADMIN permission can add session-level exclusive advisory locks to the key-value pair (65535, 65535).
- pg_try_advisory_lock_shared(key bigint)
Description: Obtains a shared session-level advisory lock if available.
Return type: Boolean
- pg_try_advisory_lock_shared(key1 int, key2 int)
Description: Obtains a shared session-level advisory lock if available.
Return type: Boolean
Note: pg_try_advisory_lock_shared works in the same way as pg_try_advisory_lock, except that pg_try_advisory_lock_shared attempts to obtain a shared lock instead of an exclusive lock.
- pg_try_advisory_xact_lock(key bigint)
Description: Obtains an exclusive transaction-level advisory lock if available.
Return type: Boolean
- pg_try_advisory_xact_lock(key1 int, key2 int)
Description: Obtains an exclusive transaction-level advisory lock if available.
Return type: Boolean
Note: pg_try_advisory_xact_lock works in the same way as pg_try_advisory_lock, except that the lock, if acquired, is automatically released at the end of the current transaction and cannot be released explicitly. Only users with the SYSADMIN permission can add transaction-level exclusive advisory locks to the key-value pair (65535, 65535).
- pg_try_advisory_xact_lock_shared(key bigint)
Description: Obtains a shared transaction-level advisory lock if available.
Return type: Boolean
- pg_try_advisory_xact_lock_shared(key1 int, key2 int)
Description: Obtains a shared transaction-level advisory lock if available.
Return type: Boolean
Note: pg_try_advisory_xact_lock_shared works in the same way as pg_try_advisory_lock_shared, except the lock, if acquired, is automatically released at the end of the current transaction and cannot be released explicitly.
- lock_cluster_ddl()
Description: Attempts to obtain a session-level exclusive advisory lock for all active CNs in the cluster.
Return type: Boolean
Note: Only users with the SYSADMIN permission can call this function.
- unlock_cluster_ddl()
Description: Attempts to add a session-level exclusive advisory lock on a CN.
Return type: Boolean
Example of session-level advisory locks:
gaussdb=# select pg_advisory_lock(1); -- Obtain three session-level advisory locks in sequence. pg_advisory_lock ------------------ (1 row) gaussdb=# select pg_advisory_lock(1,2); pg_advisory_lock ------------------ (1 row) gaussdb=# select pg_advisory_lock(2,2,'postgres'); pg_advisory_lock ------------------ (1 row) gaussdb=# select * from pg_locks; -- Query the pg_locks catalog. It is found that three advisory locks are added. locktype | database | relation | page | tuple | bucket | virtualxid | transactionid | classid | objid | objsubid | virtualtransaction | pid | sessionid | mode | granted | fastpath | locktag | global_sessionid ------------+----------+----------+------+-------+--------+------------+---------------+---------+-------+----------+--------------------+-----------------+-----------------+-----------------+---------+----------+------ -------------+------------------ relation | 12850 | 10652 | | | | | | | | | 4/27611 | 140245958915840 | 140245958915840 | AccessShareLock | t | t | 3232: 299c:0:0:0:0 | 0:0#0 virtualxid | | | | | | 4/27611 | | | | | 4/27611 | 140245958915840 | 140245958915840 | ExclusiveLock | t | t | 4:6bd b:0:0:0:7 | 0:0#0 virtualxid | | | | | | 19/16219 | | | | | 19/16219 | 140246771033856 | 140246771033856 | ExclusiveLock | t | t | 13:3f 5b:0:0:0:7 | 0:0#0 virtualxid | | | | | | 17/97293 | | | | | 17/97293 | 140246750590720 | 140246750590720 | ExclusiveLock | t | t | 11:17 c0d:0:0:0:7 | 0:0#0 advisory | 12850 | | | | | | | 0 | 1 | 1 | 4/27611 | 140245958915840 | 140245958915840 | ExclusiveLock | t | f | 3232: 0:1:1:0:b | 0:0#0 advisory | 12850 | | | | | | | 1 | 2 | 2 | 4/27611 | 140245958915840 | 140245958915840 | ExclusiveLock | t | f | 3232: 1:2:2:0:b | 0:0#0 advisory | 12850 | | | | | | | 2 | 2 | 2 | 4/27611 | 140245958915840 | 140245958915840 | ExclusiveLock | t | f | 3232: 2:2:2:0:b | 0:0#0 (7 rows) gaussdb=# select pg_advisory_unlock(1); -- Release three session-level advisory locks in sequence. pg_advisory_unlock -------------------- t (1 row) gaussdb=# select pg_advisory_unlock(1,2); pg_advisory_unlock -------------------- t (1 row) gaussdb=# select pg_advisory_unlock(2,2,'postgres'); pg_advisory_unlock -------------------- t (1 row) gaussdb=# select * from pg_locks; -- Query the pg_locks catalog. It is found that three advisory locks have been released. locktype | database | relation | page | tuple | bucket | virtualxid | transactionid | classid | objid | objsubid | virtualtransaction | pid | sessionid | mode | granted | fastpath | locktag | global_sessionid ------------+----------+----------+------+-------+--------+------------+---------------+---------+-------+----------+--------------------+-----------------+-----------------+-----------------+---------+----------+------ -------------+------------------ relation | 12850 | 10652 | | | | | | | | | 4/27618 | 140245958915840 | 140245958915840 | AccessShareLock | t | t | 3232: 299c:0:0:0:0 | 0:0#0 virtualxid | | | | | | 4/27618 | | | | | 4/27618 | 140245958915840 | 140245958915840 | ExclusiveLock | t | t | 4:6be 2:0:0:0:7 | 0:0#0 virtualxid | | | | | | 19/16254 | | | | | 19/16254 | 140246771033856 | 140246771033856 | ExclusiveLock | t | t | 13:3f 7e:0:0:0:7 | 0:0#0 virtualxid | | | | | | 17/97506 | | | | | 17/97506 | 140246750590720 | 140246750590720 | ExclusiveLock | t | t | 11:17 ce2:0:0:0:7 | 0:0#0 (4 rows) gaussdb=# select pg_advisory_lock(1); -- Obtain session-level advisory locks again. pg_advisory_lock ------------------ (1 row) gaussdb=# select pg_advisory_unlock_all(); -- Release all session-level advisory locks. pg_advisory_unlock_all ------------------------ (1 row) gaussdb=# select * from pg_locks; -- Query the pg_locks catalog. It is found that advisory locks have been released. locktype | database | relation | page | tuple | bucket | virtualxid | transactionid | classid | objid | objsubid | virtualtransaction | pid | sessionid | mode | granted | fastpath | locktag | global_sessionid ------------+----------+----------+------+-------+--------+------------+---------------+---------+-------+----------+--------------------+-----------------+-----------------+-----------------+---------+----------+------ -------------+------------------ relation | 12850 | 10652 | | | | | | | | | 4/27629 | 140245958915840 | 140245958915840 | AccessShareLock | t | t | 3232: 299c:0:0:0:0 | 0:0#0 virtualxid | | | | | | 4/27629 | | | | | 4/27629 | 140245958915840 | 140245958915840 | ExclusiveLock | t | t | 4:6be d:0:0:0:7 | 0:0#0 virtualxid | | | | | | 19/16369 | | | | | 19/16369 | 140246771033856 | 140246771033856 | ExclusiveLock | t | t | 13:3f f1:0:0:0:7 | 0:0#0 virtualxid | | | | | | 17/98194 | | | | | 17/98194 | 140246750590720 | 140246750590720 | ExclusiveLock | t | t | 11:17 f92:0:0:0:7 | 0:0#0 (4 rows)
Example of transaction-level advisory locks:
gaussdb=# select pg_advisory_xact_lock_shared(1); -- Obtain a shared transaction-level advisory lock. pg_advisory_xact_lock_shared ------------------------------ (1 row) gaussdb=# select * from pg_locks; -- Since a single statement is considered a transaction, the advisory lock is automatically released when the transaction is committed. Querying the pg_locks catalog will not show the transaction-level advisory lock. locktype | database | relation | page | tuple | bucket | virtualxid | transactionid | classid | objid | objsubid | virtualtransaction | pid | sessionid | mode | granted | fastpath | locktag | global_sessionid ------------+----------+----------+------+-------+--------+------------+---------------+---------+-------+----------+--------------------+-----------------+-----------------+-----------------+---------+----------+------ -------------+------------------ relation | 12850 | 10652 | | | | | | | | | 4/27631 | 140245958915840 | 140245958915840 | AccessShareLock | t | t | 3232: 299c:0:0:0:0 | 0:0#0 virtualxid | | | | | | 4/27631 | | | | | 4/27631 | 140245958915840 | 140245958915840 | ExclusiveLock | t | t | 4:6be f:0:0:0:7 | 0:0#0 virtualxid | | | | | | 19/16396 | | | | | 19/16396 | 140246771033856 | 140246771033856 | ExclusiveLock | t | t | 13:40 0c:0:0:0:7 | 0:0#0 virtualxid | | | | | | 17/98359 | | | | | 17/98359 | 140246750590720 | 140246750590720 | ExclusiveLock | t | t | 11:18 037:0:0:0:7 | 0:0#0 (4 rows) gaussdb=# start transaction; -- Explicitly start a transaction block. START TRANSACTION gaussdb=# select pg_advisory_xact_lock_shared(1); -- Obtain a shared transaction-level advisory lock. pg_advisory_xact_lock_shared ------------------------------ (1 row) gaussdb=# select * from pg_locks; -- Query the pg_locks catalog. It is found that an advisory lock is added. locktype | database | relation | page | tuple | bucket | virtualxid | transactionid | classid | objid | objsubid | virtualtransaction | pid | sessionid | mode | granted | fastpath | locktag | global_sessionid ------------+----------+----------+------+-------+--------+------------+---------------+---------+-------+----------+--------------------+-----------------+-----------------+-----------------+---------+----------+------ -------------+------------------ relation | 12850 | 10652 | | | | | | | | | 4/27632 | 140245958915840 | 140245958915840 | AccessShareLock | t | t | 3232: 299c:0:0:0:0 | 0:0#0 virtualxid | | | | | | 4/27632 | | | | | 4/27632 | 140245958915840 | 140245958915840 | ExclusiveLock | t | t | 4:6bf 0:0:0:0:7 | 0:0#0 virtualxid | | | | | | 19/16399 | | | | | 19/16399 | 140246771033856 | 140246771033856 | ExclusiveLock | t | t | 13:40 0f:0:0:0:7 | 0:0#0 virtualxid | | | | | | 17/98377 | | | | | 17/98377 | 140246750590720 | 140246750590720 | ExclusiveLock | t | t | 11:18 049:0:0:0:7 | 0:0#0 advisory | 12850 | | | | | | | 0 | 1 | 1 | 4/27632 | 140245958915840 | 140245958915840 | ShareLock | t | f | 3232: 0:1:1:0:b | 0:0#0 (5 rows) gaussdb=# commit; -- Commit the transaction block. COMMIT gaussdb=# select * from pg_locks; -- Query the pg_locks catalog. It is found that the transaction-level advisory lock has been automatically released. locktype | database | relation | page | tuple | bucket | virtualxid | transactionid | classid | objid | objsubid | virtualtransaction | pid | sessionid | mode | granted | fastpath | locktag | global_sessionid ------------+----------+----------+------+-------+--------+------------+---------------+---------+-------+----------+--------------------+-----------------+-----------------+-----------------+---------+----------+------ -------------+------------------ relation | 12850 | 10652 | | | | | | | | | 4/27633 | 140245958915840 | 140245958915840 | AccessShareLock | t | t | 3232: 299c:0:0:0:0 | 0:0#0 virtualxid | | | | | | 4/27633 | | | | | 4/27633 | 140245958915840 | 140245958915840 | ExclusiveLock | t | t | 4:6bf 1:0:0:0:7 | 0:0#0 virtualxid | | | | | | 19/16401 | | | | | 19/16401 | 140246771033856 | 140246771033856 | ExclusiveLock | t | t | 13:40 11:0:0:0:7 | 0:0#0 virtualxid | | | | | | 17/98385 | | | | | 17/98385 | 140246750590720 | 140246750590720 | ExclusiveLock | t | t | 11:18 051:0:0:0:7 | 0:0#0 (4 rows)
Example of attempting to obtain advisory locks:gaussdb=# select pg_try_advisory_lock_shared(1); -- Successfully attempt to obtain a shared advisory lock on object 1 when no other connections hold an advisory lock. pg_try_advisory_lock_shared ----------------------------- t (1 row) gaussdb=# select pg_advisory_unlock_all(); -- Release the advisory lock. pg_advisory_unlock_all ------------------------ (1 row) gaussdb=# select pg_advisory_lock(1); -- Obtain the exclusive advisory lock on object 1. pg_advisory_lock ------------------ (1 row) -- Keep the connection and start a new connection. gaussdb=# select pg_try_advisory_lock_shared(1); -- Failed to obtain the shared advisory lock on object 1 in a new connection because an existing connection holds an exclusive lock. pg_try_advisory_lock_shared ----------------------------- f (1 row)
Feedback
Was this page helpful?
Provide feedbackThank you very much for your feedback. We will continue working to improve the documentation.See the reply and handling status in My Cloud VOC.
For any further questions, feel free to contact us through the chatbot.
Chatbot