Reference for Explicit Transactions and syntax for the BEGIN/COMMIT/ROLLBACK statements.
BEGIN
starts a new transaction.
COMMIT
saves all changes made within the transaction, making them permanent.
ROLLBACK
discards all changes.
BEGIN
statement, followed by one or more SQL statements, and finally a COMMIT
or ROLLBACK
statement. Each statement must be sent sequentially in separate requests.
BEGIN
while a transaction is already active will return an error.COMMIT
or ROLLBACK
when no transaction is active will also result in an error.Firebolt-Protocol-Version="2.4"
or the Firebolt UI.begin_lsn
at its start and marked for successful completion with a commit_lsn
.
These identifiers are Log Sequence Numbers (LSN), which are 20-byte hexadecimal string representations that are part of a single, lexicographically increasing sequence. This structure ensures a chronological order of all transaction starts and commits in the system.
The begin_lsn
and commit_lsn
can be monitored through the information_schema.transactions views
SELECT
) within the transaction. This is useful for performing calculations or checks as part of your logic, ensuring the data you read is consistent with the state at the beginning of the transaction.
Statement Type | Examples |
---|---|
DML | INSERT , INSERT AS SELECT , UPDATE , DELETE , MERGE , TRUNCATE , DROP PARTITION |
DDL | CREATE /ALTER /DROP tables/view/indexes and databases CREATE TABLE AS SELECT , CREATE TABLE CLONE |
DQL | SELECT |
DCL | Database level rbac permissions,e.g. GRANT SELECT ON my_table TO my_role; |
BEGIN...COMMIT
block:
CREATE
/DROP USER
, CREATE
/DROP ROLE
, ASSIGN
/REVOKE ROLE
.CREATE
/DROP
/ALTER LOCATION.
COPY TO
an external resource, as it cannot be rolled back.START ENGINE
, STOP ENGINE
.COMMIT
. If the transaction is rolled back or fails, all intermediate changes are discarded.
COMMIT
command, all of its changes are permanently saved and will survive any subsequent system failures. Any system or user failure that occurs before a COMMIT
will result in the automatic rollback of the transaction, ensuring the database is not left in an inconsistent state.
ROLLBACK
command. This safely terminates the transaction session.
current transaction is aborted, commands ignored until end of transaction block
.ROLLBACK
command to end the aborted transaction before starting a new one.transaction_begin_lsn
identifies the explicit transaction to roll back.TRANSACTION
keyword is optional.Tool | Description |
---|---|
CURRENT_TRANSACTION() | A function that returns the unique identifier (begin_lsn ) for the currently active transaction. Returns empty string if no transaction is active. |
information_schema.transactions | A view that provides historical information about transactions, including their begin_lsn/commit_lsn, status (IN-PROGRESS , COMMITTED , ROLLBACKED ), start/end times, and the name of the user that initiated it. |
information_schema.engine_query_history | This view exposes the transaction_begin_lsn for each query, allowing you to group statements from the same transaction for performance or order analysis. |
UPDATE
a table within a transaction, your role must have the UPDATE
privilege on that table.
UPDATE
fails, both changes are reversed.
ALTER DATABASE
statements are executed as a single, instantaneous change.
ROLLBACK
command discards the creation of orders
and the INSERT
statement. The table orders
will not exist.