Skip to content
New issue

Have a question about this project? Sign up for a free GitHub account to open an issue and contact its maintainers and the community.

By clicking “Sign up for GitHub”, you agree to our terms of service and privacy statement. We’ll occasionally send you account related emails.

Already on GitHub? Sign in to your account

Add docs on XA transactions #19370

Draft
wants to merge 2 commits into
base: main
Choose a base branch
from
Draft
Changes from all commits
Commits
File filter

Filter by extension

Filter by extension

Conversations
Failed to load comments.
Loading
Jump to
Jump to file
Failed to load files.
Loading
Diff view
Diff view
118 changes: 118 additions & 0 deletions src/current/v25.1/transactions.md
Original file line number Diff line number Diff line change
Expand Up @@ -238,6 +238,124 @@ The limits are enforced after each statement of a transaction has been fully exe
Enabling `transaction_rows_read_err` disables a performance optimization for mutation statements in implicit transactions where CockroachDB can auto-commit without additional network round trips.
{{site.data.alerts.end}}

## XA transactions

XA (eXtended Architecture) transactions, also known as two-phase transactions, are a standard mechanism for coordinating "global transactions" that logically execute across multiple separate database systems (often referred to as "resource managers") to ensure atomicity and consistency. XA transactions are used in heterogeneous data storage environments, often involving mainframes.

An external transaction management system such as IBM Tivoli or Narayana coordinates the commit or rollback process across multiple database systems.

For more information about the XA specification, see [X/Open XA](https://en.wikipedia.org/wiki/X/Open_XA).

{{site.data.alerts.callout_danger}}
Cockroach Labs recommends using XA transactions only for legacy mainframe migrations; they are not supported for general use.
{{site.data.alerts.end}}

### Examples

CockroachDB implements the following statements in support of XA transactions:

- `PREPARE TRANSACTION`
- `COMMIT PREPARED`
- `ROLLBACK PREPARED`

#### Move money between accounts using an XA transaction

What follows is an example of a very simple XA transaction that represents moving money between accounts on two separate database systems.

1. Create a table representing each system, and insert test data.

{% include_cached copy-clipboard.html %}
~~~ sql
CREATE TABLE IF NOT EXISTS system_a (
account_id SERIAL PRIMARY KEY,
account_number VARCHAR(20) UNIQUE NOT NULL,
balance NUMERIC(12,2) NOT NULL CHECK (balance >= 0),
owner_name VARCHAR(100) NOT NULL,
created_at TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP
);

CREATE TABLE IF NOT EXISTS system_b (
account_id SERIAL PRIMARY KEY,
account_number VARCHAR(20) UNIQUE NOT NULL,
balance NUMERIC(12,2) NOT NULL CHECK (balance >= 0),
owner_name VARCHAR(100) NOT NULL,
created_at TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP
);

INSERT INTO system_a (account_number, balance, owner_name) VALUES ('A12345', 10000.00, 'Alice Smith');
INSERT INTO system_b (account_number, balance, owner_name) VALUES ('B67890', 5000.00, 'Bob Jones');
~~~

1. Start the transaction, and issue the actual SQL statements that represent actions distributed across separate systems:

{% include_cached copy-clipboard.html %}
~~~ sql
BEGIN;
WITH old_balance AS (
SELECT balance AS current_balance
FROM system_a
WHERE account_number = 'A12345'
)
UPDATE system_a
SET balance = (SELECT current_balance FROM old_balance) - 1000
WHERE account_number = 'A12345';
WITH old_balance AS (
SELECT balance AS current_balance
FROM system_b
WHERE account_number = 'B67890'
)
UPDATE system_b
SET balance = (SELECT current_balance FROM old_balance) + 1000
WHERE account_number = 'B67890';
~~~

1. Mark the transaction as an XA transaction. `PREPARE TRANSACTION` puts the transaction in a special state with the constraint that after this point, *only* `COMMIT PREPARED` or `ROLLBACK PREPARED` statements are allowed.

{% include_cached copy-clipboard.html %}
~~~ sql
PREPARE TRANSACTION 'transfer_a12345_b67890';
~~~

1. Commit (or rollback) the XA transaction:

{% include_cached copy-clipboard.html %}
~~~ sql
COMMIT PREPARED 'transfer_a_to_b';
-- ... or ROLLBACK PREPARED 'transfer_a_to_b'
~~~

### Inspect open XA transactions

{% include_cached copy-clipboard.html %}
~~~ sql
SELECT * FROM pg_prepared_xacts;
~~~

~~~
transaction | gid | prepared | owner | database
--------------+-----------------+------------------------------+-------+------------
0 | transfer_a_to_b | 2025-02-12 19:50:02.86884+00 | root | defaultdb
(1 row)
~~~

### Check the ages of XA transactions

{% include_cached copy-clipboard.html %}
~~~ sql
SELECT
transaction,
prepared,
age(clock_timestamp(), prepared) as transaction_age
FROM pg_prepared_xacts;
~~~

~~~
transaction | prepared | transaction_age
--------------+------------------------------+------------------
0 | 2025-02-12 19:50:02.86884+00 | 00:00:26.699268
(1 row)
~~~

## See also

- [`BEGIN`]({% link {{ page.version.version }}/begin-transaction.md %})
Expand Down