|
| 1 | +# subtrans_infos |
| 2 | + |
| 3 | +This extension allows you to get detailed subtransaction information for any PostgreSQL transaction ID, including: |
| 4 | + |
| 5 | +- Transaction status (in progress, committed, aborted) |
| 6 | +- Parent transaction ID |
| 7 | +- Top-level parent transaction ID |
| 8 | +- Subtransaction nesting level |
| 9 | +- Commit timestamp (when available) |
| 10 | + |
| 11 | +The extension provides comprehensive safety checks and handles PostgreSQL's internal transaction management constraints properly. |
| 12 | + |
| 13 | +## Usage |
| 14 | + |
| 15 | +The extension provides a single function: |
| 16 | + |
| 17 | +```sql |
| 18 | +subtrans_infos(xid bigint) |
| 19 | +RETURNS TABLE ( |
| 20 | + xid integer, |
| 21 | + status text, |
| 22 | + parent_xid integer, |
| 23 | + top_parent_xid integer, |
| 24 | + sub_level integer, |
| 25 | + commit_timestamp timestamptz |
| 26 | +) |
| 27 | +``` |
| 28 | + |
| 29 | +### Parameters |
| 30 | + |
| 31 | +- `xid`: The transaction ID to analyze (as a bigint) |
| 32 | + |
| 33 | +### Return Columns |
| 34 | + |
| 35 | +- `xid`: The input transaction ID (converted to integer) |
| 36 | +- `status`: Transaction status ("in progress", "committed", "aborted") |
| 37 | +- `parent_xid`: Direct parent transaction ID (NULL if top-level) |
| 38 | +- `top_parent_xid`: Top-level parent transaction ID (NULL if top-level or data unavailable) |
| 39 | +- `sub_level`: Subtransaction nesting level (NULL if top-level or data unavailable) |
| 40 | +- `commit_timestamp`: Timestamp when transaction was committed (NULL if not committed or unavailable) |
| 41 | + |
| 42 | +## Examples |
| 43 | + |
| 44 | +First, create a test table: |
| 45 | + |
| 46 | +```sql |
| 47 | +CREATE TABLE t1 (id int); |
| 48 | +``` |
| 49 | + |
| 50 | +Start a transaction with savepoints: |
| 51 | +```sql |
| 52 | +BEGIN; |
| 53 | +INSERT INTO t1 VALUES(1); |
| 54 | +SAVEPOINT a; |
| 55 | +INSERT INTO t1 VALUES(2); |
| 56 | +SAVEPOINT b; |
| 57 | +INSERT INTO t1 VALUES(3); |
| 58 | +``` |
| 59 | + |
| 60 | +Now analyze the transaction locks and subtransactions: |
| 61 | +```sql |
| 62 | +SELECT |
| 63 | + pgl.pid, |
| 64 | + pgl.locktype, |
| 65 | + pgl.mode, |
| 66 | + si.xid, |
| 67 | + si.status AS "xid status", |
| 68 | + si.parent_xid, |
| 69 | + si.top_parent_xid, |
| 70 | + si.sub_level, |
| 71 | + si.commit_timestamp |
| 72 | +FROM ( |
| 73 | + SELECT * |
| 74 | + FROM pg_locks |
| 75 | + WHERE transactionid IS NOT NULL |
| 76 | +) pgl |
| 77 | +CROSS JOIN LATERAL subtrans_infos(pgl.transactionid::text::bigint) si |
| 78 | +ORDER BY si.xid; |
| 79 | +``` |
| 80 | + |
| 81 | +Expected output (transaction IDs will vary): |
| 82 | + |
| 83 | +``` |
| 84 | + pid | locktype | mode | xid | xid status | parent_xid | top_parent_xid | sub_level | commit_timestamp |
| 85 | +--------+---------------+---------------+------+-------------+------------+----------------+-----------+------------------ |
| 86 | + 704841 | transactionid | ExclusiveLock | 1647 | in progress | | | | |
| 87 | + 704841 | transactionid | ExclusiveLock | 1648 | in progress | 1647 | 1647 | 1 | |
| 88 | + 704841 | transactionid | ExclusiveLock | 1649 | in progress | 1648 | 1647 | 2 | |
| 89 | +(3 rows) |
| 90 | +``` |
| 91 | + |
| 92 | +Complete the transaction: |
| 93 | +```sql |
| 94 | +COMMIT; |
| 95 | +``` |
| 96 | + |
| 97 | +### Example 2: Individual Transaction Analysis |
| 98 | + |
| 99 | +Query specific transaction IDs: |
| 100 | +```sql |
| 101 | +-- Check a specific transaction |
| 102 | +subtrans_infos=# SELECT * FROM subtrans_infos(1647); |
| 103 | + |
| 104 | + xid | status | parent_xid | top_parent_xid | sub_level | commit_timestamp |
| 105 | +------+-----------+------------+----------------+-----------+---------------------------- |
| 106 | + 1647 | committed | | | | 2025-09-29 10:18:52.488217 |
| 107 | +(1 row) |
| 108 | +``` |
| 109 | + |
| 110 | +### Example 3: Analyzing Aborted Subtransactions |
| 111 | + |
| 112 | +```sql |
| 113 | +subtrans_infos=# BEGIN; |
| 114 | +INSERT INTO t1 VALUES(10); |
| 115 | +SAVEPOINT sp1; |
| 116 | +INSERT INTO t1 VALUES(20); |
| 117 | +SAVEPOINT sp2; |
| 118 | +INSERT INTO t1 VALUES(30); |
| 119 | +ROLLBACK TO SAVEPOINT sp1; |
| 120 | +BEGIN |
| 121 | +INSERT 0 1 |
| 122 | +SAVEPOINT |
| 123 | +INSERT 0 1 |
| 124 | +SAVEPOINT |
| 125 | +INSERT 0 1 |
| 126 | +ROLLBACK |
| 127 | +subtrans_infos=*# SELECT |
| 128 | + si.xid, |
| 129 | + si.status, |
| 130 | + si.parent_xid, |
| 131 | + si.top_parent_xid, |
| 132 | + si.sub_level |
| 133 | +FROM pg_locks pgl |
| 134 | +CROSS JOIN LATERAL subtrans_infos(pgl.transactionid::text::bigint) si |
| 135 | +WHERE pgl.transactionid IS NOT NULL |
| 136 | +ORDER BY si.xid; |
| 137 | + xid | status | parent_xid | top_parent_xid | sub_level |
| 138 | +------+-------------+------------+----------------+----------- |
| 139 | + 1650 | in progress | | | |
| 140 | +(1 row) |
| 141 | + |
| 142 | + |
| 143 | +subtrans_infos=*# SELECT * FROM subtrans_infos(1651); |
| 144 | + xid | status | parent_xid | top_parent_xid | sub_level | commit_timestamp |
| 145 | +------+---------+------------+----------------+-----------+------------------ |
| 146 | + 1651 | aborted | 1650 | 1650 | 1 | |
| 147 | +(1 row) |
| 148 | +``` |
| 149 | + |
| 150 | +## Remarks |
| 151 | + |
| 152 | +- `top_parent_xid` and `sub_level` may be NULL when subtransaction data is not available (e.g., for very old transactions) |
| 153 | +- Commit timestamps are only available when `track_commit_timestamp` is enabled |
| 154 | +- The extension properly handles PostgreSQL's transaction ID wraparound |
| 155 | +- All operations are safe and will not crash the database server |
0 commit comments