-
Notifications
You must be signed in to change notification settings - Fork 458
Commit
This commit does not belong to any branch on this repository, and may belong to a fork outside of the repository.
Document the 'SELECT ... FOR UPDATE' statement
Fixes #6000. Summary of changes: - Add docs for the `SELECT ... FOR UPDATE` statement, including an example showing its intended use. - Update other pages re: selection queries to mention the use of `SELECT FOR UPDATE` to reduce retries and improve throughput/latency. - Update Transactions page and Perf Best Practices page to mention `SELECT FOR UPDATE` as a possible solution to thrashing/retry issues. - Add `SELECT FOR UPDATE` to SQL Statements and SQL Feature Support pages. - Add docs for new `enable_implicit_select_for_update` session and cluster setting.
- Loading branch information
1 parent
f6e96ac
commit 978cf68
Showing
12 changed files
with
188 additions
and
1 deletion.
There are no files selected for viewing
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -0,0 +1,5 @@ | ||
{{site.data.alerts.callout_info}} | ||
It's possible to mitigate read-write contention and reduce transaction retries using the following techniques: | ||
1. By performing reads using [`AS OF SYSTEM TIME`](performance-best-practices-overview.html#use-as-of-system-time-to-decrease-conflicts-with-long-running-queries). | ||
2. By using [`SELECT FOR UPDATE`](select-for-update.html) to order transactions by controlling concurrent access to one or more rows of a table. This reduces retries in scenarios where a transaction performs a read and then updates the same row it just read. | ||
{{site.data.alerts.end}} |
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -0,0 +1,12 @@ | ||
<span class="version-tag">New in v20.1</span>: The `SELECT ... FOR UPDATE` statement is used to order transactions by controlling concurrent access to one or more rows of a table. | ||
|
||
It works by locking the rows returned by a [selection query][selection], such that other transactions trying to access those rows are forced to wait for the transaction that locked the rows to finish. These other transactions are effectively put into a queue based on when they tried to read the value of the locked rows. | ||
|
||
Because this queueing happens during the read operation, the thrashing that would otherwise occur if multiple concurrently executing transactions attempt to `SELECT` the same data and then `UPDATE` the results of that selection is prevented. By preventing this thrashing, CockroachDB also prevents the [transaction retries][retries] that would otherwise occur. | ||
|
||
As a result, using `SELECT FOR UPDATE` leads to increased throughput and decreased tail latency for contended operations. | ||
|
||
<!-- Reference Links --> | ||
|
||
[retries]: transactions.html#transaction-retries | ||
[selection]: selection-queries.html |
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -0,0 +1,129 @@ | ||
--- | ||
title: SELECT FOR UPDATE | ||
summary: The SELECT FOR UPDATE statement is used to order transactions under contention. | ||
keywords: concurrency control, locking, transactions, update locking, update, contention | ||
toc: true | ||
--- | ||
|
||
{% include {{page.version.version}}/sql/select-for-update-overview.md %} | ||
|
||
## Required privileges | ||
|
||
The user must have the `SELECT` and `UPDATE` [privileges](authorization.html#assign-privileges) on the tables used as operands. | ||
|
||
## Parameters | ||
|
||
The same as for other [selection queries](selection-queries.html). | ||
|
||
## Examples | ||
|
||
### Enforce transaction order when updating the same rows | ||
|
||
In this example, we'll use `SELECT ... FOR UPDATE` to lock a row inside a transaction, forcing other transactions that want to update the same row to wait for the first transaction to complete. The other transactions that want to update the same row are effectively put into a queue based on when they first try to read the value of the row. | ||
|
||
This example assumes you are running a [local unsecured cluster](start-a-local-cluster.html). | ||
|
||
First, let's connect to the running cluster (we'll call this Terminal 1): | ||
|
||
{% include copy-clipboard.html %} | ||
~~~ shell | ||
cockroach sql --insecure | ||
~~~ | ||
|
||
Next, let's create a table and insert some rows: | ||
|
||
{% include copy-clipboard.html %} | ||
~~~ sql | ||
CREATE TABLE kv (k INT PRIMARY KEY, v INT); | ||
INSERT INTO kv (k, v) VALUES (1, 5), (2, 10), (3, 15); | ||
~~~ | ||
|
||
Next, we'll start a [transaction](transactions.html) and and lock the row we want to operate on: | ||
|
||
{% include copy-clipboard.html %} | ||
~~~ sql | ||
BEGIN; | ||
SELECT * FROM kv WHERE k = 1 FOR UPDATE; | ||
~~~ | ||
|
||
Hit enter twice in the [SQL client](cockroach-sql.html) to send the input so far to be evaluated. This will result in the following output: | ||
|
||
~~~ | ||
k | v | ||
+---+----+ | ||
1 | 5 | ||
(1 row) | ||
~~~ | ||
|
||
Now let's open another terminal and connect to the database from a second client (we'll call this Terminal 2): | ||
|
||
{% include copy-clipboard.html %} | ||
~~~ shell | ||
cockroach sql --insecure | ||
~~~ | ||
|
||
From Terminal 2, start a transaction and try to lock the same row for updates that is already being accessed by the transaction we opened in Terminal 1: | ||
|
||
{% include copy-clipboard.html %} | ||
~~~ sql | ||
BEGIN; | ||
SELECT * FROM kv WHERE k = 1 FOR UPDATE; | ||
~~~ | ||
|
||
Hit enter twice to send the input so far to be evaluated. Because Terminal 1 has already locked this row, the `SELECT ... FOR UPDATE` statement from Terminal 2 will appear to "wait". | ||
|
||
Back in Terminal 1, let's update the row and commit the transaction: | ||
|
||
{% include copy-clipboard.html %} | ||
~~~ sql | ||
UPDATE kv SET v = v + 5 WHERE k = 1; | ||
COMMIT; | ||
~~~ | ||
|
||
~~~ | ||
COMMIT | ||
~~~ | ||
|
||
Now that the transaction in Terminal 1 has committed, the transaction in Terminal 2 will be "unblocked", generating the following output, which shows the value left by the transaction in Terminal 1: | ||
|
||
~~~ | ||
k | v | ||
+---+----+ | ||
1 | 10 | ||
(1 row) | ||
~~~ | ||
|
||
The transaction in Terminal 2 can now receive input, so let's update the row in question again: | ||
|
||
{% include copy-clipboard.html %} | ||
~~~ sql | ||
UPDATE kv SET v = v + 5 WHERE k = 1; | ||
COMMIT; | ||
~~~ | ||
|
||
~~~ | ||
UPDATE 1 | ||
~~~ | ||
|
||
Finally, we commit the transaction in Terminal 2: | ||
|
||
{% include copy-clipboard.html %} | ||
~~~ sql | ||
COMMIT; | ||
~~~ | ||
|
||
~~~ | ||
COMMIT | ||
~~~ | ||
|
||
## See also | ||
|
||
- [`SELECT`](select-clause.html) | ||
- [Selection Queries](selection-queries.html) | ||
- [Understanding and avoiding transaction contention][transaction_contention] | ||
|
||
<!-- Reference links --> | ||
|
||
[transaction_contention]: performance-best-practices-overview.html#understanding-and-avoiding-transaction-contention | ||
[retries]: transactions.html#client-side-intervention | ||
[select]: select-clause.html |
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters