Skip to content

Commit

Permalink
Document nested SAVEPOINTs
Browse files Browse the repository at this point in the history
Fixes #5953.

Summary of changes:

- Update SAVEPOINT page with more examples of "general" savepoints, in
  addition to the existing "retry" savepoints

- Add a new SHOW SAVEPOINT STATUS statement page, and add it to the
  sidebar

- Update RELEASE SAVEPOINT docs to clarify "retry" savepoints
  vs. "general", and update the example
  • Loading branch information
rmloveland committed Feb 28, 2020
1 parent 2a18c9a commit 1f1dd1f
Show file tree
Hide file tree
Showing 9 changed files with 245 additions and 40 deletions.
6 changes: 6 additions & 0 deletions _includes/sidebar-data-v20.1.json
Original file line number Diff line number Diff line change
Expand Up @@ -1338,6 +1338,12 @@
"/${VERSION}/show-statistics.html"
]
},
{
"title": "<code>SHOW SAVEPOINT STATUS</code>",
"urls": [
"/${VERSION}/show-savepoint-status.html"
]
},
{
"title": "<code>SHOW TABLES</code>",
"urls": [
Expand Down
6 changes: 3 additions & 3 deletions _includes/v20.1/misc/customizing-the-savepoint-name.md
Original file line number Diff line number Diff line change
@@ -1,7 +1,7 @@
Set the `force_savepoint_restart` [session variable](set-vars.html#supported-variables) to `true` to enable using a custom name for the restart savepoint (for example, because you are using an ORM that wants to use its own names for savepoints).
Set the `force_savepoint_restart` [session variable](set-vars.html#supported-variables) to `true` to enable using a custom name for the [retry savepoint](savepoint.html#savepoints-for-client-side-transaction-retries) (for example, because you are using an ORM that wants to use its own names for savepoints).

Once this variable is set, the [`SAVEPOINT`](savepoint.html) statement will accept any name for the savepoint, not just `cockroach_restart`. This allows compatibility with existing code that uses a single savepoint per transaction as long as that savepoint occurs before any statements that access data stored in non-virtual tables.
Once this variable is set, the [`SAVEPOINT`](savepoint.html) statement will accept any name for the retry savepoint, not just `cockroach_restart`. This allows compatibility with existing code that uses a single savepoint per transaction as long as that savepoint occurs before any statements that access data stored in non-virtual tables.

{{site.data.alerts.callout_danger}}
The `force_savepoint_restart` variable changes the semantics of CockroachDB savepoints so that `RELEASE SAVEPOINT <your-custom-name>` functions as a real commit. Note that the existence of this variable and its behavior does not change the fact that CockroachDB savepoints can only be used as a part of the transaction retry protocol.
The `force_savepoint_restart` variable changes the semantics of CockroachDB savepoints so that `RELEASE SAVEPOINT <your-custom-name>` functions as a real commit.
{{site.data.alerts.end}}
3 changes: 0 additions & 3 deletions _includes/v20.1/misc/savepoint-limitations.md

This file was deleted.

4 changes: 2 additions & 2 deletions v20.1/begin-transaction.md
Original file line number Diff line number Diff line change
Expand Up @@ -36,15 +36,15 @@ In CockroachDB, the following are aliases for the `BEGIN` statement:
`READ` | Set the transaction access mode to `READ ONLY` or `READ WRITE`. The current transaction access mode is also exposed as the [session variable](show-vars.html) `transaction_read_only`.<br><br>**Default**: `READ WRITE`
`AS OF SYSTEM TIME` | Execute the transaction using the database contents "as of" a specified time in the past.<br/><br/> The `AS OF SYSTEM TIME` clause can be used only when the transaction is read-only. If the transaction contains any writes, or if the `READ WRITE` mode is specified, an error will be returned.<br/><br/>For more information, see [AS OF SYSTEM TIME](as-of-system-time.html).<br/><br/>

CockroachDB now only supports `SERIALIZABLE` isolation, so transactions can no longer be meaningfully set to any other `ISOLATION LEVEL`. In previous versions of CockroachDB, you could set transactions to `SNAPSHOT` isolation, but that feature has been removed.
CockroachDB now only supports `SERIALIZABLE` isolation, so transactions can no longer be meaningfully set to any other `ISOLATION LEVEL`. In previous versions of CockroachDB, you could set transactions to `SNAPSHOT` isolation, but that feature has been removed.

## Examples

### Begin a transaction

#### Use default settings

Without modifying the `BEGIN` statement, the transaction uses `SERIALIZABLE` isolation and `NORMAL` priority.
Without modifying the `BEGIN` statement, the transaction uses `NORMAL` priority.

{% include copy-clipboard.html %}
~~~ sql
Expand Down
1 change: 1 addition & 0 deletions v20.1/commit-transaction.md
Original file line number Diff line number Diff line change
Expand Up @@ -81,3 +81,4 @@ If you are using transactions that CockroachDB will [automatically retry](transa
- [`RELEASE SAVEPOINT`](release-savepoint.html)
- [`ROLLBACK`](rollback-transaction.html)
- [`SAVEPOINT`](savepoint.html)
- [`SHOW SAVEPOINT STATUS`](show-savepoint-status.html)
34 changes: 13 additions & 21 deletions v20.1/release-savepoint.md
Original file line number Diff line number Diff line change
@@ -1,16 +1,14 @@
---
title: RELEASE SAVEPOINT
summary: Commit a transaction's changes once there are no retry errors with the RELEASE SAVEPOINT statement in CockroachDB.
summary: Remove all open savepoints from the current transaction with the RELEASE SAVEPOINT statement in CockroachDB.
toc: true
---

When using [advanced client-side transaction retries](advanced-client-side-transaction-retries.html), the `RELEASE SAVEPOINT` statement commits the transaction.
The `RELEASE SAVEPOINT` statement causes all open savepoints back to and including the named savepoint to be removed from the transaction stack.

If statements in the transaction [generated any non-retry errors](transactions.html#error-handling), `RELEASE SAVEPOINT` is equivalent to [`ROLLBACK`](rollback-transaction.html), which aborts the transaction and discards all updates made by its statements.

Note that although issuing this statement commits the transaction, you must also issue a subsequent [`COMMIT`](commit-transaction.html) statement to prepare the connection for the next transaction.
It functions as a [`COMMIT`](commit-transaction.html) when it releases the outermost savepoint in a stack of nested savepoints. This includes when it is used as part of the legacy [client-side transaction retry protocol](transactions.html#client-side-intervention). Note that although issuing this statement commits the transaction, you must also issue a subsequent [`COMMIT`](commit-transaction.html) statement to prepare the connection for the next transaction.

{% include {{ page.version.version }}/misc/savepoint-limitations.md %}
If statements in the transaction [generated any non-retry errors](transactions.html#error-handling), `RELEASE SAVEPOINT` is equivalent to [`ROLLBACK`](rollback-transaction.html), which aborts the transaction and discards all updates made by its statements.

## Synopsis

Expand All @@ -26,9 +24,9 @@ No [privileges](authorization.html#assign-privileges) are required to release a

Parameter | Description
--------- | -----------
name | The name of the savepoint. Defaults to `cockroach_restart`, but may be customized. For more information, see [Customizing the savepoint name](#customizing-the-savepoint-name).
name | The name of the savepoint.

## Customizing the savepoint name
## Customizing the name of a retry savepoint

{% include {{ page.version.version }}/misc/customizing-the-savepoint-name.md %}

Expand All @@ -40,25 +38,19 @@ After declaring a [`SAVEPOINT`](savepoint.html), commit the transaction with `RE

{% include copy-clipboard.html %}
~~~ sql
> BEGIN;

> SAVEPOINT cockroach_restart;

> UPDATE products SET inventory = 0 WHERE sku = '8675309';

> INSERT INTO orders (customer, sku, status) VALUES (1001, '8675309', 'new');

> RELEASE SAVEPOINT cockroach_restart;

> COMMIT;
BEGIN;
SAVEPOINT update_inventory;
UPDATE products SET inventory = 0 WHERE sku = '8675309';
INSERT INTO orders (customer, sku, status) VALUES (1001, '8675309', 'new');
RELEASE SAVEPOINT update_inventory;
COMMIT;
~~~

{{site.data.alerts.callout_danger}}This example assumes you're using <a href="transactions.html#client-side-intervention">client-side intervention to handle transaction retries</a>.{{site.data.alerts.end}}

## See also

- [Transactions](transactions.html)
- [`SAVEPOINT`](savepoint.html)
- [`SHOW SAVEPOINT STATUS`](show-savepoint-status.html)
- [`ROLLBACK`](rollback-transaction.html)
- [`BEGIN`](begin-transaction.html)
- [`COMMIT`](commit-transaction.html)
1 change: 1 addition & 0 deletions v20.1/rollback-transaction.md
Original file line number Diff line number Diff line change
Expand Up @@ -89,3 +89,4 @@ For examples of retrying transactions in an application, check out the transacti
- [`COMMIT`](commit-transaction.html)
- [`SAVEPOINT`](savepoint.html)
- [`RELEASE SAVEPOINT`](release-savepoint.html)
- [`SHOW SAVEPOINT STATUS`](show-savepoint-status.html)
171 changes: 160 additions & 11 deletions v20.1/savepoint.md
Original file line number Diff line number Diff line change
@@ -1,12 +1,10 @@
---
title: SAVEPOINT
summary: Identify your intent to retry aborted transactions with the SAVEPOINT statement in CockroachDB.
summary: Define a SAVEPOINT within the current transaction
toc: true
---

The `SAVEPOINT` statement defines the intent to retry [transactions](transactions.html) using the CockroachDB-provided function for client-side transaction retries. For more information, see [Transaction Retries](transactions.html#transaction-retries).

{% include {{ page.version.version }}/misc/savepoint-limitations.md %}
A savepoint is a placeholder inside a transaction that is used to allow (non-DDL) statements that are executed after the savepoint to be [rolled back](rollback-transaction.html). When rolled back, the database is restored to the state that existed prior to the savepoint. Clients can use multiple nested savepoints in a transaction.

## Synopsis

Expand All @@ -22,17 +20,144 @@ No [privileges](authorization.html#assign-privileges) are required to create a s

Parameter | Description
--------- | -----------
name | The name of the savepoint. Defaults to `cockroach_restart`, but may be customized. For more information, see [Customizing the savepoint name](#customizing-the-savepoint-name).
name | The name of the savepoint.

## Customizing the savepoint name
## Examples

{% include {{ page.version.version }}/misc/customizing-the-savepoint-name.md %}
The examples below use the following table:

{% include copy-clipboard.html %}
~~~ sql
CREATE TABLE kv (k INT, v INT);
~~~

### Basic usage

To establish a savepoint inside a transaction:

{% include copy-clipboard.html %}
~~~ sql
SAVEPOINT foo;
~~~

To roll back a transaction partially to a previously established savepoint:

{% include copy-clipboard.html %}
~~~ sql
ROLLBACK TO SAVEPOINT foo;
~~~

To forget a savepoint, and keep the effects of statements executed after the savepoint was established, use [`RELEASE SAVEPOINT`](release-savepoint.html):

{% include copy-clipboard.html %}
~~~ sql
RELEASE SAVEPOINT foo;
~~~

For example, the transaction below will insert the values `(1,1)` and `(3,3)` into the table, but not `(2,2)`:

{% include copy-clipboard.html %}
~~~ sql
BEGIN;
INSERT INTO kv VALUES (1,1);
SAVEPOINT my_savepoint;
INSERT INTO kv VALUES (2,2);
ROLLBACK TO SAVEPOINT my_savepoint;
INSERT INTO kv VALUES (3,3);
COMMIT;
~~~

### Multi-level commit / rollback

[`RELEASE SAVEPOINT`](release-savepoint.html) and [`ROLLBACK TO SAVEPOINT`](rollback-transaction.html) can both refer to a savepoint "higher" in the nesting hierarchy. When this occurs, all of the savepoints "under" the nesting are automatically released / rolled back too.

To insert both `(2,2)` and `(4,4)`:

{% include copy-clipboard.html %}
~~~ sql
BEGIN;
SAVEPOINT foo;
INSERT INTO kv VALUES (2,2);
SAVEPOINT bar;
INSERT INTO kv VALUES (4,4);
RELEASE SAVEPOINT foo;
COMMIT;
~~~

This inserts nothing - both are rolled back:

{% include copy-clipboard.html %}
~~~ sql
BEGIN;
SAVEPOINT foo;
INSERT INTO kv VALUES (5,5);
SAVEPOINT bar;
INSERT INTO kv VALUES (5,5);
ROLLBACK TO SAVEPOINT foo;
COMMIT;
~~~

This demonstrates that the name "bar" is not visible after it was rolled back over:

{% include copy-clipboard.html %}
~~~ sql
BEGIN;
SAVEPOINT foo;
SAVEPOINT bar;
ROLLBACK TO SAVEPOINT foo;
RELEASE SAVEPOINT bar; -- error: savepoint "bar" does not exist
COMMIT;
~~~

#### Savepoints and prepared statements

```
prepare a as select 1;
root@localhost:26257/defaultdb OPEN> prepare a as select 1;
PREPARE
Time: 1.177ms
rollback to savepoint foo;
root@localhost:26257/defaultdb OPEN> rollback to savepoint foo;
ROLLBACK
Time: 145µs
execute a;
root@localhost:26257/defaultdb OPEN> execute a;
?column?
------------
1
(1 row)
Time: 468µs
show savepoint status;
root@localhost:26257/defaultdb OPEN> show savepoint status;
savepoint_name | is_restart_savepoint
-----------------+-----------------------
foo | false
(1 row)
Time: 427µs
rollback;
root@localhost:26257/defaultdb OPEN> rollback;
ROLLBACK
## Example
Time: 384µs
After you `BEGIN` the transaction, you must create the savepoint to identify that if the transaction contends with another transaction for resources and "loses", you intend to use [client-side transaction retries](transactions.html#transaction-retries).
root@localhost:26257/defaultdb>
```

Applications using `SAVEPOINT` must also include functions to execute retries with [`ROLLBACK TO SAVEPOINT `](rollback-transaction.html#retry-a-transaction).
### Savepoints for client-side transaction retries

If you intend to implement [advanced client-side transaction retries](advanced-client-side-transaction-retries.html), after you `BEGIN` the transaction, you must create an outermost savepoint named `cockroach_restart`. This will identify that if the transaction contends with another transaction for resources and "loses", you intend to use [client-side transaction retries](transactions.html#transaction-retries).

Applications using `SAVEPOINT` for client-side transaction retries must also include functions to execute retries with [`ROLLBACK TO SAVEPOINT `](rollback-transaction.html#retry-a-transaction).

A savepoint used for client-side transaction retries must be the outermost savepoint in a transaction; it cannot be nested inside other savepoints.

{% include copy-clipboard.html %}
~~~ sql
Expand Down Expand Up @@ -64,12 +189,36 @@ Applications using `SAVEPOINT` must also include functions to execute retries wi
> COMMIT;
~~~

### Showing savepoint status

Use the [`SHOW SAVEPOINT STATUS`](show-savepoint-status.html) statement to see how many savepoints are active in the current transaction:

{% include copy-clipboard.html %}
~~~ sql
SHOW SAVEPOINT STATUS;
~~~

~~~
savepoint_name | is_restart_savepoint
-----------------+-----------------------
foo | false
bar | false
(2 rows)
~~~

Note that the `is_restart_savepoint` column will be true if the savepoint is [being used to implement client-side transaction retries](#savepoints-for-client-side-transaction-retries).

### Customizing the name of retry savepoints

{% include {{ page.version.version }}/misc/customizing-the-savepoint-name.md %}

## See also

- [Transactions](transactions.html)
- [`SHOW SAVEPOINT STATUS`](show-savepoint-status.html)
- [`RELEASE SAVEPOINT`](release-savepoint.html)
- [`ROLLBACK`](rollback-transaction.html)
- [`BEGIN`](begin-transaction.html)
- [`COMMIT`](commit-transaction.html)
- [Transactions](transactions.html)
- [Retryable transaction example code in Java using JDBC](build-a-java-app-with-cockroachdb.html)
- [CockroachDB Architecture: Transaction Layer](architecture/transaction-layer.html)
59 changes: 59 additions & 0 deletions v20.1/show-savepoint-status.md
Original file line number Diff line number Diff line change
@@ -0,0 +1,59 @@
---
title: SHOW SAVEPOINT STATUS
summary: The SHOW SAVEPOINT STATUS statement lists the active savepoints in the current transaction.
toc: true
---

The `SHOW SAVEPOINT STATUS` [statement](sql-statements.html) lists the active [savepoints](savepoint.html) in the current [transaction](transactions.html).

## Required privileges

No [privileges](authorization.html#assign-privileges) are required to create or show a savepoint. However, privileges are required for each statement within a transaction.

## Response

The following fields are returned for each savepoint.

Field | Description
------|------------
`savepoint_name` | The name of the savepoint.
`is_restart_savepoint` | Whether the savepoint is [being used to implement client-side transaction retries](savepoint.html#savepoints-for-client-side-transaction-retries).

## Example

First, open a [transaction](transactions.html) and create a [savepoint](savepoint.html):

{% include copy-clipboard.html %}
~~~ sql
BEGIN;
SAVEPOINT foo;
~~~

{% include copy-clipboard.html %}
~~~ sql
SHOW SAVEPOINT STATUS;
~~~

~~~
savepoint_name | is_restart_savepoint
-----------------+-----------------------
foo | false
(1 row)
~~~

Remove the savepoint from the transaction with [`RELEASE SAVEPOINT`](release-savepoint.html), and exit the transaction with [`COMMIT`](commit-transaction.html):

{% include copy-clipboard.html %}
~~~ sql
RELEASE SAVEPOINT foo;
COMMIT;
~~~

## See also

- [`SAVEPOINT`](savepoint.html)
- [`RELEASE SAVEPOINT`](release-savepoint.html)
- [`ROLLBACK`](rollback-transaction.html)
- [`BEGIN`](begin-transaction.html)
- [`COMMIT`](commit-transaction.html)
- [Transactions](transactions.html)

0 comments on commit 1f1dd1f

Please sign in to comment.