A locking read, an
UPDATE, or a
DELETE generally set record locks
on every index record that is scanned in the processing of an SQL
statement. It does not matter whether there are
WHERE conditions in the statement that would
exclude the row. InnoDB does not remember the
exact WHERE condition, but only knows which
index ranges were scanned. The locks are normally
next-key locks that also
block inserts into the “gap” immediately before the
record. However, gap locking
can be disabled explicitly, which causes next-key locking not to
be used. For more information, see
Section 17.7.1, “InnoDB Locking”. The transaction isolation level
can also affect which locks are set; see
Section 17.7.2.1, “Transaction Isolation Levels”.
If a secondary index is used in a search and the index record
locks to be set are exclusive, InnoDB also
retrieves the corresponding clustered index records and sets locks
on them.
If you have no indexes suitable for your statement and MySQL must scan the entire table to process the statement, every row of the table becomes locked, which in turn blocks all inserts by other users to the table. It is important to create good indexes so that your queries do not scan more rows than necessary.
InnoDB sets specific types of locks as follows.
SELECT ... FROMis a consistent read, reading a snapshot of the database and setting no locks unless the transaction isolation level is set toSERIALIZABLE. ForSERIALIZABLElevel, the search sets shared next-key locks on the index records it encounters. However, only an index record lock is required for statements that lock rows using a unique index to search for a unique row.SELECT ... FOR UPDATEandSELECT ... FOR SHAREstatements that use a unique index acquire locks for scanned rows, and release the locks for rows that do not qualify for inclusion in the result set (for example, if they do not meet the criteria given in theWHEREclause). However, in some cases, rows might not be unlocked immediately because the relationship between a result row and its original source is lost during query execution. For example, in aUNION, scanned (and locked) rows from a table might be inserted into a temporary table before evaluating whether they qualify for the result set. In this circumstance, the relationship of the rows in the temporary table to the rows in the original table is lost and the latter rows are not unlocked until the end of query execution.For locking reads (
SELECTwithFOR UPDATEorFOR SHARE),UPDATE, andDELETEstatements, the locks that are taken depend on whether the statement uses a unique index with a unique search condition or a range-type search condition.For a unique index with a unique search condition,
InnoDBlocks only the index record found, not the gap before it.For other search conditions, and for non-unique indexes,
InnoDBlocks the index range scanned, using gap locks or next-key locks to block insertions by other sessions into the gaps covered by the range. For information about gap locks and next-key locks, see Section 17.7.1, “InnoDB Locking”.
For index records the search encounters,
SELECT ... FOR UPDATEblocks other sessions from doingSELECT ... FOR SHAREor from reading in certain transaction isolation levels. Consistent reads ignore any locks set on the records that exist in the read view.UPDATE ... WHERE ...sets an exclusive next-key lock on every record the search encounters. However, only an index record lock is required for statements that lock rows using a unique index to search for a unique row.When
UPDATEmodifies a clustered index record, implicit locks are taken on affected secondary index records. TheUPDATEoperation also takes shared locks on affected secondary index records when performing duplicate check scans prior to inserting new secondary index records, and when inserting new secondary index records.DELETE FROM ... WHERE ...sets an exclusive next-key lock on every record the search encounters. However, only an index record lock is required for statements that lock rows using a unique index to search for a unique row.INSERTsets an exclusive lock on the inserted row. This lock is an index-record lock, not a next-key lock (that is, there is no gap lock) and does not prevent other sessions from inserting into the gap before the inserted row.Prior to inserting the row, a type of gap lock called an insert intention gap lock is set. This lock signals the intent to insert in such a way that multiple transactions inserting into the same index gap need not wait for each other if they are not inserting at the same position within the gap. Suppose that there are index records with values of 4 and 7. Separate transactions that attempt to insert values of 5 and 6 each lock the gap between 4 and 7 with insert intention locks prior to obtaining the exclusive lock on the inserted row, but do not block each other because the rows are nonconflicting.
If a duplicate-key error occurs, a shared lock on the duplicate index record is set. This use of a shared lock can result in deadlock should there be multiple sessions trying to insert the same row if another session already has an exclusive lock. This can occur if another session deletes the row. Suppose that an
InnoDBtablet1has the following structure:CREATE TABLE t1 (i INT, PRIMARY KEY (i)) ENGINE = InnoDB;Now suppose that three sessions perform the following operations in order:
Session 1:
START TRANSACTION; INSERT INTO t1 VALUES(1);Session 2:
START TRANSACTION; INSERT INTO t1 VALUES(1);Session 3:
START TRANSACTION; INSERT INTO t1 VALUES(1);Session 1:
ROLLBACK;The first operation by session 1 acquires an exclusive lock for the row. The operations by sessions 2 and 3 both result in a duplicate-key error and they both request a shared lock for the row. When session 1 rolls back, it releases its exclusive lock on the row and the queued shared lock requests for sessions 2 and 3 are granted. At this point, sessions 2 and 3 deadlock: Neither can acquire an exclusive lock for the row because of the shared lock held by the other.
A similar situation occurs if the table already contains a row with key value 1 and three sessions perform the following operations in order:
Session 1:
START TRANSACTION; DELETE FROM t1 WHERE i = 1;Session 2:
START TRANSACTION; INSERT INTO t1 VALUES(1);Session 3:
START TRANSACTION; INSERT INTO t1 VALUES(1);Session 1:
COMMIT;The first operation by session 1 acquires an exclusive lock for the row. The operations by sessions 2 and 3 both result in a duplicate-key error and they both request a shared lock for the row. When session 1 commits, it releases its exclusive lock on the row and the queued shared lock requests for sessions 2 and 3 are granted. At this point, sessions 2 and 3 deadlock: Neither can acquire an exclusive lock for the row because of the shared lock held by the other.
INSERT ... ON DUPLICATE KEY UPDATEdiffers from a simpleINSERTin that an exclusive lock rather than a shared lock is placed on the row to be updated when a duplicate-key error occurs. An exclusive index-record lock is taken for a duplicate primary key value. An exclusive next-key lock is taken for a duplicate unique key value.REPLACEis done like anINSERTif there is no collision on a unique key. Otherwise, an exclusive next-key lock is placed on the row to be replaced.INSERT INTO T SELECT ... FROM S WHERE ...sets an exclusive index record lock (without a gap lock) on each row inserted intoT. If the transaction isolation level isREAD COMMITTED,InnoDBdoes the search onSas a consistent read (no locks). Otherwise,InnoDBsets shared next-key locks on rows fromS.InnoDBhas to set locks in the latter case: During roll-forward recovery using a statement-based binary log, every SQL statement must be executed in exactly the same way it was done originally.CREATE TABLE ... SELECT ...performs theSELECTwith shared next-key locks or as a consistent read, as forINSERT ... SELECT.When a
SELECTis used in the constructsREPLACE INTO t SELECT ... FROM s WHERE ...orUPDATE t ... WHERE col IN (SELECT ... FROM s ...),InnoDBsets shared next-key locks on rows from tables.InnoDBsets an exclusive lock on the end of the index associated with theAUTO_INCREMENTcolumn while initializing a previously specifiedAUTO_INCREMENTcolumn on a table.With
innodb_autoinc_lock_mode=0,InnoDBuses a specialAUTO-INCtable lock mode where the lock is obtained and held to the end of the current SQL statement (not to the end of the entire transaction) while accessing the auto-increment counter. Other clients cannot insert into the table while theAUTO-INCtable lock is held. The same behavior occurs for “bulk inserts” withinnodb_autoinc_lock_mode=1. Table-levelAUTO-INClocks are not used withinnodb_autoinc_lock_mode=2. For more information, See Section 17.6.1.6, “AUTO_INCREMENT Handling in InnoDB”.InnoDBfetches the value of a previously initializedAUTO_INCREMENTcolumn without setting any locks.If a
FOREIGN KEYconstraint is defined on a table, any insert, update, or delete that requires the constraint condition to be checked sets shared record-level locks on the records that it looks at to check the constraint.InnoDBalso sets these locks in the case where the constraint fails.LOCK TABLESsets table locks, but it is the higher MySQL layer above theInnoDBlayer that sets these locks.InnoDBis aware of table locks ifinnodb_table_locks = 1(the default) andautocommit = 0, and the MySQL layer aboveInnoDBknows about row-level locks.Otherwise,
InnoDB's automatic deadlock detection cannot detect deadlocks where such table locks are involved. Also, because in this case the higher MySQL layer does not know about row-level locks, it is possible to get a table lock on a table where another session currently has row-level locks. However, this does not endanger transaction integrity, as discussed in Section 17.7.5.2, “Deadlock Detection”.LOCK TABLESacquires two locks on each table ifinnodb_table_locks=1(the default). In addition to a table lock on the MySQL layer, it also acquires anInnoDBtable lock. To avoid acquiringInnoDBtable locks, setinnodb_table_locks=0. If noInnoDBtable lock is acquired,LOCK TABLEScompletes even if some records of the tables are being locked by other transactions.In MySQL 8.4,
innodb_table_locks=0has no effect for tables locked explicitly withLOCK TABLES ... WRITE. It does have an effect for tables locked for read or write byLOCK TABLES ... WRITEimplicitly (for example, through triggers) or byLOCK TABLES ... READ.All
InnoDBlocks held by a transaction are released when the transaction is committed or aborted. Thus, it does not make much sense to invokeLOCK TABLESonInnoDBtables inautocommit=1mode because the acquiredInnoDBtable locks would be released immediately.You cannot lock additional tables in the middle of a transaction because
LOCK TABLESperforms an implicitCOMMITandUNLOCK TABLES.