diff --git a/_includes/sidebar-data-v20.1.json b/_includes/sidebar-data-v20.1.json
index 5593c57be27..97296ee413e 100644
--- a/_includes/sidebar-data-v20.1.json
+++ b/_includes/sidebar-data-v20.1.json
@@ -1200,6 +1200,12 @@
"/${VERSION}/select-clause.html"
]
},
+ {
+ "title": "SELECT FOR UPDATE
",
+ "urls": [
+ "/${VERSION}/select-for-update.html"
+ ]
+ },
{
"title": "SET
<session variable>",
"urls": [
diff --git a/_includes/v20.1/misc/mitigate-contention-note.md b/_includes/v20.1/misc/mitigate-contention-note.md
new file mode 100644
index 00000000000..ffe3cff554a
--- /dev/null
+++ b/_includes/v20.1/misc/mitigate-contention-note.md
@@ -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}}
diff --git a/_includes/v20.1/misc/session-vars.html b/_includes/v20.1/misc/session-vars.html
index ea62bb41303..9655d7a67f3 100644
--- a/_includes/v20.1/misc/session-vars.html
+++ b/_includes/v20.1/misc/session-vars.html
@@ -95,6 +95,18 @@
Yes |
+
+
+ enable_implicit_select_for_update
+ |
+ New in v20.1: Indicates whether UPDATE statements acquire locks using the FOR UPDATE locking mode during their initial row scan, which improves performance for contended workloads. For more information about how FOR UPDATE locking works, see the documentation for SELECT FOR UPDATE . |
+
+ on
+ |
+ Yes |
+ Yes |
+
+
enable_zig_zag_join
diff --git a/_includes/v20.1/sql/select-for-update-overview.md b/_includes/v20.1/sql/select-for-update-overview.md
new file mode 100644
index 00000000000..206b5deacba
--- /dev/null
+++ b/_includes/v20.1/sql/select-for-update-overview.md
@@ -0,0 +1,12 @@
+New in v20.1: 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.
+
+
+
+[retries]: transactions.html#transaction-retries
+[selection]: selection-queries.html
diff --git a/_includes/v20.1/sql/settings/settings.md b/_includes/v20.1/sql/settings/settings.md
index 3dfbbd05285..ced295cb6fa 100644
--- a/_includes/v20.1/sql/settings/settings.md
+++ b/_includes/v20.1/sql/settings/settings.md
@@ -38,6 +38,7 @@
|
server.user_login.timeout | duration | 10s | timeout after which client authentication times out if some system range is unavailable (0 = no timeout) |
server.web_session_timeout | duration | 168h0m0s | the duration that a newly created web session will be valid |
sql.defaults.default_int_size | integer | 8 | the size, in bytes, of an INT type |
+sql.defaults.implicit_select_for_update.enabled | boolean | true | default value for enable_implicit_select_for_update session setting; enables FOR UPDATE locking during the row-fetch phase of mutation statements |
sql.defaults.results_buffer.size | byte size | 16 KiB | default size of the buffer that accumulates results for a statement or a batch of statements before they are sent to the client. This can be overridden on an individual connection with the 'results_buffer_size' parameter. Note that auto-retries generally only happen while no results have been delivered to the client, so reducing this size can increase the number of retriable errors a client receives. On the other hand, increasing the buffer size can increase the delay until the client receives the first result row. Updating the setting only affects new connections. Setting to 0 disables any buffering. |
sql.defaults.serial_normalization | enumeration | rowid | default handling of SERIAL in table definitions [rowid = 0, virtual_sequence = 1, sql_sequence = 2] |
sql.distsql.max_running_flows | integer | 500 | maximum number of concurrent flows that can be run on a node |
diff --git a/v20.1/performance-best-practices-overview.md b/v20.1/performance-best-practices-overview.md
index e114102b798..1dd94595ae5 100644
--- a/v20.1/performance-best-practices-overview.md
+++ b/v20.1/performance-best-practices-overview.md
@@ -383,6 +383,8 @@ To avoid contention, multiple strategies can be applied:
[`INSERT`](insert.html)/[`UPDATE`](update.html)/[`DELETE`](delete.html)/[`UPSERT`](upsert.html)
clauses together in a single SQL statement.
+- Use the [`SELECT FOR UPDATE`](select-for-update.html) statement in scenarios where a transaction performs a read and then updates the row(s) it just read. It orders 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-queries.html), 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 that is ordered based on when they try to read the value of the locked row(s).
+
- When replacing values in a row, use [`UPSERT`](upsert.html) and
specify values for all columns in the inserted rows. This will
usually have the best performance under contention, compared to
diff --git a/v20.1/select-clause.md b/v20.1/select-clause.md
index b2968698f80..063c0e456ee 100644
--- a/v20.1/select-clause.md
+++ b/v20.1/select-clause.md
@@ -525,10 +525,17 @@ Results from two or more queries can be combined together as follows:
- Using [set operations](selection-queries.html#set-operations) to combine rows
using inclusion/exclusion rules.
+### Row-level locking for concurrency control with `SELECT FOR UPDATE`
+
+{% include {{page.version.version}}/sql/select-for-update-overview.md %}
+
+For an example showing how to use it, see [`SELECT FOR UPDATE`](select-for-update.html).
+
## See also
- [Scalar Expressions](scalar-expressions.html)
- [Selection Clauses](selection-queries.html#selection-clauses)
+- [`SELECT FOR UPDATE`](select-for-update.html)
- [Set Operations](selection-queries.html#set-operations)
- [Table Expressions](table-expressions.html)
- [Ordering Query Results](query-order.html)
diff --git a/v20.1/select-for-update.md b/v20.1/select-for-update.md
new file mode 100644
index 00000000000..26d4d2d316c
--- /dev/null
+++ b/v20.1/select-for-update.md
@@ -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]
+
+
+
+[transaction_contention]: performance-best-practices-overview.html#understanding-and-avoiding-transaction-contention
+[retries]: transactions.html#client-side-intervention
+[select]: select-clause.html
diff --git a/v20.1/selection-queries.md b/v20.1/selection-queries.md
index 56ece833ee4..1fc2c94a9db 100644
--- a/v20.1/selection-queries.md
+++ b/v20.1/selection-queries.md
@@ -504,6 +504,12 @@ EXPLAIN SELECT * FROM employees WHERE emp_no > 300025 ORDER BY emp_no LIMIT 25;
Using a sequential (i.e., non-[UUID](uuid.html)) primary key creates hot spots in the database for write-heavy workloads, since concurrent [`INSERT`](insert.html)s to the table will attempt to write to the same (or nearby) underlying [ranges](architecture/overview.html#architecture-range). This can be mitigated by designing your schema with [multi-column primary keys which include a monotonically increasing column](performance-best-practices-overview.html#use-multi-column-primary-keys).
{{site.data.alerts.end}}
+## Row-level locking for concurrency control with `SELECT FOR UPDATE`
+
+{% include {{page.version.version}}/sql/select-for-update-overview.md %}
+
+For an example showing how to use it, see [`SELECT FOR UPDATE`](select-for-update.html).
+
## Composability
[Selection clauses](#selection-clauses) are defined in the context of selection queries. [Table expressions](table-expressions.html) are defined in the context of the `FROM` sub-clause of [`SELECT`](select-clause.html). Nevertheless, they can be integrated with one another to form more complex queries or statements.
@@ -612,6 +618,7 @@ For example:
## See also
- [Simple `SELECT` Clause](select-clause.html)
+- [`SELECT FOR UPDATE`](select-for-update.html)
- [Table Expressions](table-expressions.html)
- [Ordering Query Results](query-order.html)
- [Limiting Query Results](limit-offset.html)
diff --git a/v20.1/sql-feature-support.md b/v20.1/sql-feature-support.md
index 569fdcc10a4..6a4585c9b58 100644
--- a/v20.1/sql-feature-support.md
+++ b/v20.1/sql-feature-support.md
@@ -106,6 +106,7 @@ table tr td:nth-child(2) {
`UPSERT` | ✓ | PostgreSQL, MSSQL Extension | [`UPSERT` documentation](upsert.html)
`EXPLAIN` | ✓ | Common Extension | [`EXPLAIN` documentation](explain.html)
`SELECT INTO` | Alternative | Common Extension | You can replicate similar functionality using [`CREATE TABLE`](create-table.html) and then `INSERT INTO ... SELECT ...`.
+ `SELECT ... FOR UPDATE` | ✓ | Common Extension | [`SELECT FOR UPDATE` documentation](select-for-update.html)
### Clauses
diff --git a/v20.1/sql-statements.md b/v20.1/sql-statements.md
index f5b6da87e25..6c935c880e9 100644
--- a/v20.1/sql-statements.md
+++ b/v20.1/sql-statements.md
@@ -21,6 +21,7 @@ Statement | Usage
[`IMPORT INTO`](import-into.html) | Bulk-insert CSV data into an existing table.
[`INSERT`](insert.html) | Insert rows into a table.
[`SELECT`](select-clause.html) | Select specific rows and columns from a table and optionally compute derived values.
+[`SELECT ... FOR UPDATE`](select-for-update.html) | Order transactions by controlling concurrent access to one or more rows of a table.
[`TABLE`](selection-queries.html#table-clause) | Select all rows and columns from a table.
[`TRUNCATE`](truncate.html) | Delete all rows from specified tables.
[`UPDATE`](update.html) | Update rows in a table.
diff --git a/v20.1/transactions.md b/v20.1/transactions.md
index feecd97c873..bd3da018f01 100644
--- a/v20.1/transactions.md
+++ b/v20.1/transactions.md
@@ -66,7 +66,9 @@ Type | Description
## Transaction retries
-Transactions may require retries if they experience deadlock or [read/write contention](performance-best-practices-overview.html#understanding-and-avoiding-transaction-contention) with other concurrent transactions which cannot be resolved without allowing potential [serializable anomalies](https://en.wikipedia.org/wiki/Serializability). (However, it's possible to mitigate read-write conflicts 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).)
+Transactions may require retries if they experience deadlock or [read/write contention](performance-best-practices-overview.html#understanding-and-avoiding-transaction-contention) with other concurrent transactions which cannot be resolved without allowing potential [serializable anomalies](https://en.wikipedia.org/wiki/Serializability).
+
+{% include {{page.version.version}}/misc/mitigate-contention-note.md %}
There are two cases in which transaction retries occur:
@@ -156,6 +158,8 @@ To handle these types of errors you have the following options:
2. **Most users, such as application authors**: Abort the transaction using the [`ROLLBACK`](rollback-transaction.html) statement, and then reissue all of the statements in the transaction. For an example, see the [Client-side intervention example](#client-side-intervention-example).
3. **Advanced users, such as library authors**: Use the [`SAVEPOINT`](savepoint.html) statement to create retryable transactions. Retryable transactions can improve performance because their priority is increased each time they are retried, making them more likely to succeed the longer they're in your system. For instructions showing how to do this, see [Advanced Client-Side Transaction Retries](advanced-client-side-transaction-retries.html).
+{% include {{page.version.version}}/misc/mitigate-contention-note.md %}
+
#### Client-side intervention example
{% include {{page.version.version}}/misc/client-side-intervention-example.md %}