SHOW LOCKS¶
Lists all running transactions that have locks on resources. The command can be used to show locks for the current user in all the user’s sessions or all users in the account.
For information about transactions and resource locking, see Transactions.
- See also:
Syntax¶
SHOW LOCKS [ IN ACCOUNT ]
Parameters¶
IN ACCOUNT
Returns all locks across all users in the account. This parameter only applies when executed by users with the ACCOUNTADMIN role (account administrators).
For all other roles, the function only shows locks across all sessions for the current user.
Output¶
The command output shows lock metadata in the following columns:
Column |
Description |
---|---|
|
A fully qualified table name or a transaction ID. |
|
|
|
Transaction ID (a signed 64-bit integer). |
|
Timestamp that specifies when the transaction started executing. |
|
Current status of the transaction: |
|
Timestamp that specifies when the lock was acquired. |
|
Internal/system-generated identifier for the SQL statement. |
|
Session ID (visible to users with the ACCOUNTADMIN role only). |
Usage notes¶
Columns that start with the prefix
is_
return eitherY
(yes) orN
(no).The command does not require a running warehouse to execute.
The command returns a maximum of 10K records for the specified object type, as dictated by the access privileges for the role used to execute the command; any records above the 10K limit are not returned, even with a filter applied.
To view results for which more than 10K records exist, query the corresponding view (if one exists) in the Snowflake Information Schema.
To post-process the output of this command, you can use the RESULT_SCAN function, which treats the output as a table that can be queried.
The command output includes the IDs for all running transactions that have locks on resources. These IDs can be used as input for SYSTEM$ABORT_TRANSACTION to abort a specified transaction.
For hybrid tables, this command displays a lock only if a transaction is blocked, or is blocking another transaction.
Examples¶
In this example, a transaction is holding a lock on the specified standard table (the table named in the resource
column).
SHOW LOCKS;
+---------------------------+------------+---------------------+-------------------------------+---------+-------------------------------+--------------------------------------+
| resource | type | transaction | transaction_started_on | status | acquired_on | query_id |
|---------------------------+------------+---------------------+-------------------------------+---------+-------------------------------+--------------------------------------|
| CALIBAN_DB.PUBLIC.WEATHER | PARTITIONS | 1721330303831000000 | 2024-07-18 12:18:23.831 -0700 | HOLDING | 2024-07-18 12:18:49.832 -0700 | 01b5c1c6-0002-8691-0000-a9950068a0c6 |
+---------------------------+------------+---------------------+-------------------------------+---------+-------------------------------+--------------------------------------+
In this example, a transaction is holding a row-level lock on a hybrid table. Another transaction is waiting on that lock.
SHOW LOCKS;
+---------------------+------+---------------------+-------------------------------+---------+-------------+--------------------------------------+
| resource | type | transaction | transaction_started_on | status | acquired_on | query_id |
|---------------------+------+---------------------+-------------------------------+---------+-------------+--------------------------------------|
| 1721165584820000000 | ROW | 1721165584820000000 | 2024-07-16 14:33:04.820 -0700 | HOLDING | NULL | |
| 1721165584820000000 | ROW | 1721165674582000000 | 2024-07-16 14:34:34.582 -0700 | WAITING | NULL | 01b5b715-0002-852b-0000-a99500665352 |
+---------------------+------+---------------------+-------------------------------+---------+-------------+--------------------------------------+