Row Locking
On this page
SingleStore transactions use standard 2-phase locking for concurrency control to ensure serializability.
SingleStore takes row locks on write operations (for example, DELETE
, INSERT
, or UPDATE
).
Columnstore tables either lock at the row level or the partition level, depending on the columnstore_
value.
SingleStore doesn’t implement a deadlock detection algorithm to break deadlocks.
Acquiring Row Locks
Consider the following example table:
CREATE TABLE tabs (c1 INT PRIMARY KEY, c2 INT, c3 INT, KEY(c2));
There are two different ways queries acquire row locks in SingleStore:
-
The query is scanning a secondary key to run the write operation.
For example, the query DELETE FROM tabs WHERE c2 = 1
will seek and scan the secondary index onc2
to run theDELETE
operation.When the query finds a row where c2 = 1
, it will seek into the primary key to acquire the row lock before marking the row as deleted. -
The query is scanning the primary key to run the write operation.
For example, the query DELETE FROM tabs WHERE c1 = 1
will seek and scan the primary key onc1
to run theDELETE
operation.Since the query is already scanning the primary key, the index scan itself will acquire row locks to avoid an extra seek into the primary key (as is done when DELETE
is scanning the secondary key).
While scanning the primary key, the lock will be acquired before running any filters in the WHERE
clause since the index scan operation itself cannot run those filters.DELETE FROM tabs WHERE c1 = 1 AND c3 = 1
locks rows where c3
is not 1
.c3
is not 1
), for applications running concurrent DELETE
queries, this operation is often not fast enough to avoid deadlocks.DELETE FROM tabs WHERE c1 = 1 AND c3 = 1
and DELETE FROM tabs WHERE c1 = 1 AND c3 = 2
will never deadlock if c1
is not the primary key.
The following example demonstrates how multi-table filters may lock rows that do not match the filters.
UPDATE stock JOIN product ON stock.qty = 10 AND stock.id = product.id SET ...
This query locks all the rows of the table stock
where stock.
, including the rows where stock.
is not equal to product.
.
For columnstore tables, there is no difference in locking when filtering on key or non-key columns.
Extra Deadlocks in SingleStore Due to Sharding
In a single box database, concurrent write operations on a table that scan the same index in a specific direction (either forward or reverse) cannot deadlock.
In SingleStore, the index is partitioned up amongst shards that are spread across a cluster of leaf nodes.DELETE
commands that run at the same time, starting on two different partitions (say partitions 0 and 1).DELETE
operations runs first on partition 0 and the second runs first on partition 1.
Single partition DELETE
operations don’t have this issue.DELETE
operation by using a shard key filter in the WHERE
clause.
If the deadlocks are too frequent, see the ERROR 1205 (HY000): Lock wait timeout exceeded; try restarting transaction topic.
Last modified: August 18, 2023