` | If using [nested savepoints](savepoint.html#nested-savepoints), rolls back and restarts the [sub-transaction](transactions.html#sub-transactions) started at the corresponding `SAVEPOINT` statement.
+
+## Savepoints and row locks
+
+{% include {{page.version.version}}/sql/savepoints-and-row-locks.md %}
-## Example
+## Examples
### Rollback a transaction
@@ -71,9 +85,15 @@ Typically, an application conditionally executes rollbacks, but we can see their
+----------+---------+
~~~
+### Rollback a sub-transaction
+
+The `ROLLBACK TO SAVEPOINT` statement rolls back and restarts the [sub-transaction](transactions.html#sub-transactions) started at the corresponding `SAVEPOINT` statement.
+
+For examples showing how to use `ROLLBACK TO SAVEPOINT` to rollback a sub-transaction, see [the `SAVEPOINT` documentation on nested savepoints](savepoint.html#nested-savepoints).
+
### Retry a transaction
-To use [advanced client-side transaction retries](advanced-client-side-transaction-retries.html), an application must execute `ROLLBACK TO SAVEPOINT` after detecting a `40001` / `retry transaction` error:
+When using [advanced client-side transaction retries](advanced-client-side-transaction-retries.html), use `ROLLBACK TO SAVEPOINT` to handle a transaction that needs to be retried (identified via the `40001` error code or `retry transaction` string in the error message), and then re-execute the statements you want the transaction to contain.
{% include copy-clipboard.html %}
~~~ sql
@@ -84,8 +104,9 @@ For examples of retrying transactions in an application, check out the transacti
## See also
+- [`SAVEPOINT`](savepoint.html)
- [Transactions](transactions.html)
- [`BEGIN`](begin-transaction.html)
- [`COMMIT`](commit-transaction.html)
-- [`SAVEPOINT`](savepoint.html)
- [`RELEASE SAVEPOINT`](release-savepoint.html)
+- [`SHOW SAVEPOINT STATUS`](show-savepoint-status.html)
diff --git a/v20.1/savepoint.md b/v20.1/savepoint.md
index b2f5fe4be51..968ebc7f65f 100644
--- a/v20.1/savepoint.md
+++ b/v20.1/savepoint.md
@@ -1,12 +1,12 @@
---
title: SAVEPOINT
-summary: Identify your intent to retry aborted transactions with the SAVEPOINT statement in CockroachDB.
+summary: Start a sub-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).
+A savepoint is a marker that defines the beginning of a [sub-transaction](transactions.html#sub-transactions). This marker can be later used to commit or roll back just the effects of the sub-transaction without affecting the progress of the enclosing (sub-)transaction. Sub-transactions can be nested.
-{% include {{ page.version.version }}/misc/savepoint-limitations.md %}
+{% include {{page.version.version}}/sql/savepoint-ddl-rollbacks.md %}
## Synopsis
@@ -22,54 +22,271 @@ 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. [Nested savepoints](savepoint.html#nested-savepoints) can use any name. [Retry savepoints](savepoint.html#savepoints-for-client-side-transaction-retries) default to using the name `cockroach_restart`, but this can be customized using a session variable. For more information, see [Customizing the retry savepoint name](savepoint.html#customizing-the-retry-savepoint-name).
-## Customizing the savepoint name
+## Savepoints and row locks
-{% include {{ page.version.version }}/misc/customizing-the-savepoint-name.md %}
+{% include {{page.version.version}}/sql/savepoints-and-row-locks.md %}
-## Example
+## Examples
-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).
+The examples below use the following table:
-Applications using `SAVEPOINT` must also include functions to execute retries with [`ROLLBACK TO SAVEPOINT `](rollback-transaction.html#retry-a-transaction).
+{% include copy-clipboard.html %}
+~~~ sql
+CREATE TABLE kv (k INT PRIMARY KEY, v INT);
+~~~
+
+### Basic usage
+
+To establish a savepoint inside a transaction:
+
+{% include copy-clipboard.html %}
+~~~ sql
+SAVEPOINT foo;
+~~~
+
+{{site.data.alerts.callout_info}}
+Due to the [rules for identifiers in our SQL grammar](keywords-and-identifiers.html#identifiers), `SAVEPOINT foo` and `SAVEPOINT Foo` define the same savepoint, whereas `SAVEPOINT "Foo"` defines another.
+{{site.data.alerts.end}}
+
+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;
+~~~
+
+### Nested savepoints
+
+Savepoints can be nested. [`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. Specifically:
+
+- When a previous savepoint is rolled back, the statements entered after that savepoint are also rolled back.
+
+- When a previous savepoint is released, it commits; the statements entered after that savepoint are also committed.
+
+### Multi-level rollback with `ROLLBACK TO SAVEPOINT`
+
+Savepoints can be arbitrarily nested, and rolled back to the outermost level so that every subsequent statement is rolled back.
+
+For example, this transaction does not insert anything into the table. Both `INSERT`s are rolled back:
+
+{% include copy-clipboard.html %}
+~~~ sql
+BEGIN;
+SAVEPOINT foo;
+INSERT INTO kv VALUES (5,5);
+SAVEPOINT bar;
+INSERT INTO kv VALUES (6,6);
+ROLLBACK TO SAVEPOINT foo;
+COMMIT;
+~~~
+
+### Multi-level commit with `RELEASE SAVEPOINT`
+
+Changes committed by releasing a savepoint commit all of the statements entered after that savepoint.
+
+For example, the following transaction inserts both `(2,2)` and `(4,4)` into the table when it releases the outermost savepoint:
+
+{% 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;
+~~~
+
+### Multi-level rollback and commit in the same transaction
+
+Changes partially committed by a savepoint release can be rolled back by an outer savepoint.
+
+For example, the following transaction inserts only value `(5, 5)`. The values `(6,6)` and `(7,7)` are rolled back.
+
+{% include copy-clipboard.html %}
+~~~ sql
+BEGIN;
+INSERT INTO kv VALUES (5,5);
+SAVEPOINT foo;
+INSERT INTO kv VALUES (6,6);
+SAVEPOINT bar;
+INSERT INTO kv VALUES (7,7);
+RELEASE SAVEPOINT bar;
+ROLLBACK TO SAVEPOINT foo;
+COMMIT;
+~~~
+
+### Error recovery in sub-transactions with `ROLLBACK TO SAVEPOINT`
+
+If `ROLLBACK TO SAVEPOINT` is used after a database error, it can also cancel the error state of the transaction. Database errors move a transaction (or a sub-transaction) into an "Aborted" state. In this state, the transaction will not execute any further SQL statements.
+
+You can use `ROLLBACK TO SAVEPOINT` to recover from a logical error in a sub-transaction. Logical errors include:
+
+- Unique index error (duplicate row)
+- Failed foreign key constraint check (row does not exist in referenced table)
+- Mistakes in queries (reference a column that does not exist)
+
+In addition, you can check the status of a sub-transaction using the `SHOW TRANSACTION STATUS` statement as shown below.
+
+For example:
{% include copy-clipboard.html %}
~~~ sql
-> BEGIN;
+BEGIN;
+SAVEPOINT error1;
+INSERT INTO kv VALUES (5,5); -- Duplicate key error
+~~~
+
+~~~
+ERROR: duplicate key value (k)=(5) violates unique constraint "primary"
+SQLSTATE: 23505
~~~
{% include copy-clipboard.html %}
~~~ sql
-> SAVEPOINT cockroach_restart;
+SHOW TRANSACTION STATUS;
+~~~
+
+~~~
+ TRANSACTION STATUS
+----------------------
+ Aborted
+(1 row)
+~~~
+
+{% include copy-clipboard.html %}
+~~~ sql
+ROLLBACK TO SAVEPOINT error1;
+INSERT INTO kv VALUES (6,6);
+COMMIT;
+~~~
+
+### Savepoint name visibility
+
+The name of a savepoint that was rolled back over is no longer visible afterward.
+
+For example, in the transaction below, 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;
+COMMIT;
+~~~
+
~~~
+ERROR: savepoint bar does not exist
+SQLSTATE: 3B001
+~~~
+
+The [SQL client](cockroach-sql.html) prompt will now display an error state, which you can clear by entering [`ROLLBACK`](rollback-transaction.html):
{% include copy-clipboard.html %}
~~~ sql
-> UPDATE products SET inventory = 0 WHERE sku = '8675309';
+? ERROR> ROLLBACK;
+~~~
+
~~~
+ROLLBACK
+~~~
+
+#### Savepoints and prepared statements
+
+Prepared statements (`PREPARE` / `EXECUTE`) are not transactional. Therefore, prepared statements are not invalidated upon savepoint rollback. As a result, the prepared statement was saved and executed inside the transaction, despite the rollback to the prior savepoint:
{% include copy-clipboard.html %}
~~~ sql
-> INSERT INTO orders (customer, sku, status) VALUES (1001, '8675309', 'new');
+BEGIN;
+SAVEPOINT foo;
+PREPARE bar AS SELECT 1;
+ROLLBACK TO SAVEPOINT foo;
+EXECUTE bar;
+COMMIT;
~~~
+~~~
+ ?column?
+------------
+ 1
+(1 row)
+~~~
+
+### Savepoints for client-side transaction retries
+
+{% include {{page.version.version}}/sql/retry-savepoints.md %}
+
+The example below shows basic usage of a retry savepoint:
+
{% include copy-clipboard.html %}
~~~ sql
-> RELEASE SAVEPOINT cockroach_restart;
+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;
~~~
+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).
+
+Note that you can [customize the retry savepoint name](#customizing-the-retry-savepoint-name) to something other than `cockroach_restart` with a session variable if you need to.
+
+#### Customizing the retry savepoint name
+
+{% include {{page.version.version}}/misc/customizing-the-savepoint-name.md %}
+
+### 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
-> COMMIT;
+SHOW SAVEPOINT STATUS;
~~~
+~~~
+ savepoint_name | is_initial_savepoint
+-----------------+-----------------------
+ foo | true
+ bar | false
+ baz | false
+(3 rows)
+~~~
+
+Note that the `is_initial_savepoint` column will be true if the savepoint is the outermost savepoint in the transaction.
+
## 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)
diff --git a/v20.1/show-savepoint-status.md b/v20.1/show-savepoint-status.md
new file mode 100644
index 00000000000..d3bcc60f1de
--- /dev/null
+++ b/v20.1/show-savepoint-status.md
@@ -0,0 +1,71 @@
+---
+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.
+
+## Synopsis
+
+
+ {% include {{ page.version.version }}/sql/diagrams/show_savepoint_status.html %}
+
+
+## Response
+
+The following fields are returned for each savepoint.
+
+Field | Description
+------|------------
+`savepoint_name` | The name of the savepoint.
+`is_initial_savepoint` | Whether the savepoint is the outermost savepoint in the transaction.
+
+## Example
+
+First, open a [transaction](transactions.html) using [`BEGIN`](begin-transaction.html), and create a [sub-transaction](transactions.html#sub-transactions) using a [savepoint](savepoint.html):
+
+{% include copy-clipboard.html %}
+~~~ sql
+BEGIN;
+SAVEPOINT foo;
+~~~
+
+Next, use the `SHOW SAVEPOINT STATUS` statement to list the active savepoints in the current sub-transaction.
+
+{% include copy-clipboard.html %}
+~~~ sql
+SHOW SAVEPOINT STATUS;
+~~~
+
+~~~
+ savepoint_name | is_initial_savepoint
+-----------------+-----------------------
+ foo | true
+(1 row)
+~~~
+
+Currently, there is only one savepoint.
+
+We can commit this sub-transaction by issuing the [`RELEASE SAVEPOINT`](release-savepoint.html) statement. Then, we clear the connection for the next transaction by issuing a [`COMMIT`](commit-transaction.html) statement.
+
+{% include copy-clipboard.html %}
+~~~ sql
+RELEASE SAVEPOINT foo;
+COMMIT;
+~~~
+
+If we did not want to commit this sub-transaction, but restart it instead, we would have issued a [`ROLLBACK TO SAVEPOINT`](rollback-transaction.html#rollback-a-sub-transaction).
+
+## 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)
diff --git a/v20.1/sql-feature-support.md b/v20.1/sql-feature-support.md
index ff1182e0532..e631021963c 100644
--- a/v20.1/sql-feature-support.md
+++ b/v20.1/sql-feature-support.md
@@ -65,7 +65,7 @@ table tr td:nth-child(2) {
`BEGIN` | ✓ | Standard | [`BEGIN` documentation](begin-transaction.html)
`COMMIT` | ✓ | Standard | [`COMMIT` documentation](commit-transaction.html)
`ROLLBACK` | ✓ | Standard | [`ROLLBACK` documentation](rollback-transaction.html)
- `SAVEPOINT` | ✓ | CockroachDB Extension | While `SAVEPOINT` is part of the SQL standard, we only support [our extension of it](transactions.html#transaction-retries)
+ `SAVEPOINT` | ✓ | CockroachDB Extension | New in v20.1: CockroachDB supports nested sub-transactions using [`SAVEPOINT`](savepoint.html)
### Indexes
diff --git a/v20.1/sql-statements.md b/v20.1/sql-statements.md
index 76401b177e4..fed40db9b73 100644
--- a/v20.1/sql-statements.md
+++ b/v20.1/sql-statements.md
@@ -90,9 +90,10 @@ Statement | Usage
----------|------------
[`BEGIN`](begin-transaction.html)| Initiate a [transaction](transactions.html).
[`COMMIT`](commit-transaction.html) | Commit the current [transaction](transactions.html).
-[`RELEASE SAVEPOINT`](release-savepoint.html) | When using the CockroachDB-provided function for client-side [transaction retries](transactions.html#transaction-retries), commit the transaction's changes once there are no retry errors.
-[`ROLLBACK`](rollback-transaction.html) | Discard all updates made by the current [transaction](transactions.html) or, when using the CockroachDB-provided function for client-side [transaction retries](transactions.html#transaction-retries), rollback to the savepoint and retry the transaction.
-[`SAVEPOINT`](savepoint.html) | When using the CockroachDB-provided function for client-side [transaction retries](transactions.html#transaction-retries), start a retryable transaction.
+[`SAVEPOINT`](savepoint.html) | Start a [sub-transaction](transactions.html#sub-transactions).
+[`RELEASE SAVEPOINT`](release-savepoint.html) | Commit a [sub-transaction](transactions.html#sub-transactions).
+[`ROLLBACK TO SAVEPOINT`](rollback-transaction.html#rollback-a-sub-transaction) | Roll back and restart the [sub-transaction](transactions.html#sub-transactions) started at the corresponding `SAVEPOINT` statement.
+[`ROLLBACK`](rollback-transaction.html) | Rolls back the current [transaction](transactions.html) and all of its [sub-transaction](transactions.html#sub-transactions), discarding all transactional updates made by statements inside the transaction.
[`SET TRANSACTION`](set-transaction.html) | Set the priority for the session or for an individual [transaction](transactions.html).
[`SHOW`](show-vars.html) | View the current [transaction settings](transactions.html).
diff --git a/v20.1/transactions.md b/v20.1/transactions.md
index c66fbdd3db7..ca48a51c1e7 100644
--- a/v20.1/transactions.md
+++ b/v20.1/transactions.md
@@ -14,21 +14,19 @@ For a detailed discussion of CockroachDB transaction semantics, see [How Cockroa
Each of the following SQL statements control transactions in some way.
-| Statement | Function |
-|------------------------------------------------------+---------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------|
-| [`BEGIN`](begin-transaction.html) | Initiate a transaction, as well as control its [priority](#transaction-priorities). |
-| [`SET TRANSACTION`](set-transaction.html) | Control a transaction's [priority](#transaction-priorities). |
-| [`COMMIT`](commit-transaction.html) | Commit a regular transaction, or clear the connection after committing a transaction using the [advanced retry protocol](advanced-client-side-transaction-retries.html). |
-| [`ROLLBACK`](rollback-transaction.html) | Abort a transaction and roll the database back to its state before the transaction began. |
-| [`SHOW`](show-vars.html) | Display the current transaction settings. |
-| [`SAVEPOINT`](savepoint.html) | (**Advanced**) Used to implement [advanced client-side transaction retries](advanced-client-side-transaction-retries.html), which can improve performance and avoid starvation when transactions are retried. |
-| [`RELEASE SAVEPOINT`](release-savepoint.html) | (**Advanced**) Commit a [retryable transaction](advanced-client-side-transaction-retries.html). |
-| [`ROLLBACK TO SAVEPOINT`](rollback-transaction.html) | (**Advanced**) Handle [retry errors](#error-handling) by rolling back a transaction's changes and increasing its priority. |
+| Statement | Function |
+|------------------------------------------------------+--------------------------------------------------------------------------------------------------------------------------------------------------------------------------|
+| [`BEGIN`](begin-transaction.html) | Initiate a transaction, as well as control its [priority](#transaction-priorities). |
+| [`SET TRANSACTION`](set-transaction.html) | Control a transaction's [priority](#transaction-priorities). |
+| [`COMMIT`](commit-transaction.html) | Commit a regular transaction, or clear the connection after committing a transaction using the [advanced retry protocol](advanced-client-side-transaction-retries.html). |
+| [`ROLLBACK`](rollback-transaction.html) | Abort a transaction and roll the database back to its state before the transaction began. |
+| [`SHOW`](show-vars.html) | Display the current transaction settings. |
+| [`SAVEPOINT`](savepoint.html) | Used for [sub-transactions](#sub-transactions); also used to implement [advanced client-side transaction retries](advanced-client-side-transaction-retries.html). |
+| [`RELEASE SAVEPOINT`](release-savepoint.html) | Commit a [sub-transaction](#sub-transactions); also used for [retryable transactions](advanced-client-side-transaction-retries.html). |
+| [`ROLLBACK TO SAVEPOINT`](rollback-transaction.html) | Roll back a [sub-transaction](#sub-transactions); also used to handle [retryable transaction errors](advanced-client-side-transaction-retries.html). |
{{site.data.alerts.callout_info}}
-The **Advanced** statements above are used to implement [advanced client-side transaction retries](advanced-client-side-transaction-retries.html), and are mostly of use to driver and ORM authors.
-
-Application developers who are using a framework or library that does not have advanced retry logic built in should implement an application-level retry loop with exponential backoff as shown in [Client-side intervention](#client-side-intervention).
+Application developers who are using a framework or library that does not have [advanced retry logic](advanced-client-side-transaction-retries.html) built in should implement an application-level retry loop with exponential backoff as shown in [Client-side intervention](#client-side-intervention).
{{site.data.alerts.end}}
## Syntax
@@ -156,7 +154,7 @@ To handle these types of errors you have the following options:
- **Python** developers can use [SQLAlchemy](https://www.sqlalchemy.org) with the [`cockroachdb-python` adapter](https://github.com/cockroachdb/cockroachdb-python). For more information, see [Build a Python App with CockroachDB](build-a-python-app-with-cockroachdb-sqlalchemy.html).
- **Java** developers accessing the database with [JDBC](https://jdbc.postgresql.org) can re-use the example code implementing retry logic shown in [Build a Java app with CockroachDB](build-a-java-app-with-cockroachdb.html).
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).
+3. **Advanced users, such as library authors**: See [Advanced Client-Side Transaction Retries](advanced-client-side-transaction-retries.html).
{% include {{page.version.version}}/misc/mitigate-contention-note.md %}
@@ -170,6 +168,28 @@ Transactions in CockroachDB lock data resources that are written during their ex
For more details about transaction contention and best practices for avoiding contention, see [Understanding and Avoiding Transaction Contention](performance-best-practices-overview.html#understanding-and-avoiding-transaction-contention).
+## Sub-transactions
+
+New in v20.1: CockroachDB supports the nesting of transactions using [savepoints](savepoint.html). These nested transactions are also known as sub-transactions.
+
+Just as [`COMMIT`][commit] and [`ROLLBACK`][rollback_transaction] are used to commit and discard entire transactions, respectively, [`RELEASE SAVEPOINT`][release_savepoint] and [`ROLLBACK TO SAVEPOINT`][rollback_to_savepoint] are used to commit and discard sub-transactions. This relationship is shown in the table below:
+
+| Statement | Effect |
+|--------------------------------------------------+----------------------------------------------------|
+| [`COMMIT`][commit] | Commit an entire transaction. |
+| [`ROLLBACK`][rollback_transaction] | Discard an entire transaction. |
+| [`RELEASE SAVEPOINT`][release_savepoint] | Commit (really, forget) the named sub-transaction. |
+| [`ROLLBACK TO SAVEPOINT`][rollback_to_savepoint] | Discard the changes in the named sub-transaction. |
+
+For more information, including examples showing how to use savepoints to create sub-transactions, see [the savepoints documentation](savepoint.html#examples).
+
+
+
+[commit]: commit-transaction.html
+[rollback]: rollback-transaction.html
+[release_savepoint]: release-savepoint.html
+[rollback_to_savepoint]: rollback-transaction.html#rollback-a-sub-transaction
+
## Transaction priorities
Every transaction in CockroachDB is assigned an initial **priority**. By default, that priority is `NORMAL`, but for transactions that should be given preference in [high-contention scenarios](performance-best-practices-overview.html#understanding-and-avoiding-transaction-contention), the client can set the priority within the [`BEGIN`](begin-transaction.html) statement: