LOCK TABLES and UNLOCK TABLES
Syntax
LOCK TABLES tbl_name [[AS] alias] lock_type [, tbl_name [[AS] alias] lock_type] ... lock_type: READ [LOCAL] | [LOW_PRIORITY] WRITE | WRITE CONCURRENT UNLOCK TABLES
Description
Option | Description |
---|---|
READ | Read lock, no writes allowed |
READ LOCAL | Read lock, but allow concurrent inserts |
WRITE | Exclusive write lock. No other connections can read or write to this table |
LOW_PRIORITY WRITE | Exclusive write lock, but allow new read locks on the table until we get the write lock. |
WRITE CONCURRENT | Exclusive write lock, but allow READ LOCAL locks to the table. |
MariaDB enables client sessions to acquire table locks explicitly for the purpose of cooperating with other sessions for access to tables, or to prevent other sessions from modifying tables during periods when a session requires exclusive access to them. A session can acquire or release locks only for itself. One session cannot acquire locks for another session or release locks held by another session.
Locks may be used to emulate transactions or to get more speed when updating tables.
LOCK TABLES
explicitly acquires table locks for the current client session.
Table locks can be acquired for base tables or views. To use LOCK TABLES
,
you must have the LOCK TABLES
privilege, and the SELECT
privilege for
each object to be locked. See GRANT
For view locking, LOCK TABLES
adds all base tables used in the view to the
set of tables to be locked and locks them automatically. If you lock a table
explicitly with LOCK TABLES
, any tables used in triggers are also locked
implicitly, as described in Triggers and Implicit Locks.
UNLOCK TABLES
explicitly releases any table locks held by the
current session.
Another use for UNLOCK TABLES
is to release the global read lock acquired
with the FLUSH TABLES WITH READ LOCK
statement, which enables you to lock
all tables in all databases. See FLUSH
. (This is a very
convenient way to get backups if you have a file system such as Veritas that
can take snapshots in time.)
Limitations
LOCK tables
doesn't work when using Galera cluster. You may experience crashes or locks when used with Galera.
LOCK TABLES works on XtraDB/InnoDB tables only if the innodb_table_locks system variable is set to 1 and autocommit is set to 0. Please note that no error message will be returned on LOCK TABLES with innodb_table_locks = 0.
LOCK TABLES
implicitly commits the active transaction, if any. Also, starting a transaction always releases all table locks acquired with LOCK TABLES. This means that there is no way to have table locks and an active transaction at the same time. The only exceptions are the transactions in autocommit mode. To preserve the data integrity between transactional and non-transactional tables, the GET_LOCK() function can be used.
While a connection holds an explicit read lock on a table, it cannot modify it. If you try, the following error will be produced:
ERROR 1099 (HY000): Table 'tab_name' was locked with a READ lock and can't be updated
While a connection holds an explicit lock on a table, it cannot access a non-locked table. If you try, the following error will be produced:
ERROR 1100 (HY000): Table 'tab_name' was not locked with LOCK TABLES
While a connection holds an explicit lock on a table, it cannot issue the following: INSERT DELAYED, CREATE TABLE, CREATE TABLE ... LIKE, and DDL statements involving stored programs and views (except for triggers). If you try, the following error will be produced:
ERROR 1192 (HY000): Can't execute the given command because you have active locked tables or an active transaction
LOCK TABLES
can not be used in stored routines - if you try, the following error will be produced on creation:
ERROR 1314 (0A000): LOCK is not allowed in stored procedures