Managing Transactions
A transaction is a customized sequence of database operations, which form an integral unit of work. In GaussDB, you can start, set, commit, and roll back transactions. GaussDB supports the following transaction isolation levels: READ COMMITTED, REPEATABLE READ, and SERIALIZABLE. SERIALIZABLE is equivalent to REPEATABLE READ.
Controlling Transactions
The following describes transaction operations supported by the database:
- Starting transactions
You can use the START TRANSACTION or BEGIN syntax to start a transaction. For details, see START TRANSACTION and BEGIN.
- Setting transactions
You can use the SET TRANSACTION or SET LOCAL TRANSACTION syntax to set transactions. For details, see SET TRANSACTION.
- Committing transactions
You can commit all operations of a transaction using COMMIT or END. For details, see COMMIT | END.
- Rolling back transactions
Rollback indicates that the system cancels all changes that a transaction has made to a database if the transaction fails to be executed due to a fault. For details, see ROLLBACK.
Transaction Isolation Levels
A transaction isolation level specifies how concurrent transactions process the same object.
The isolation level cannot be changed after the first data manipulation statement (SELECT, INSERT, DELETE, UPDATE, FETCH, or COPY) in a transaction is executed.
- READ COMMITTED: A transaction can read only committed data. This is the default value.
The SELECT statement accesses the snapshot of the database taken when the query begins. The SELECT statement can also access the data modifications in its transaction, regardless of whether they have been committed. Note that different database snapshots may be available to two consecutive SELECT statements for the same transaction, because data may be committed for other transactions while the first SELECT statement is executed.
At the READ COMMITTED level, the execution of each statement begins with a new snapshot, which contains all the transactions that have been committed by the execution time. Therefore, during a transaction, a statement can access the result of other committed transactions. Check whether a single statement always accesses absolutely consistent data in a database.
Transaction isolation at this level meets the requirements of many applications, and is fast and easy to use. However, applications performing complicated queries and updates may require data that is more consistent than this level can provide.
- REPEATABLE READ: At this level, a transaction can only read data committed before it starts. Uncommitted data or data committed in other concurrent transactions cannot be read. However, a query can read earlier data modifications in its transaction, regardless of whether they have been committed. READ COMMITTED differs from this level in that a transaction reads the snapshot taken at the start of the transaction, not at the beginning of the current query within the transaction. Therefore, the SELECT statement within a transaction always reads the same data, and cannot read data committed by other concurrent transactions after the transaction starts. Applications at this level must be able to retry transactions, because serialization failures may occur.
- SERIALIZABLE: Currently, GaussDB does not support this isolation level. Setting this isolation level is equivalent to REPEATABLE READ.
REPEATABLE READ is implemented based on multi-version snapshots and write skew may occur. To avoid this scenario, perform the SELECT FOR UPDATE operation on the rows involved in the transaction. The following is an example of write skew:
Scenario 1: Table a has the id and value columns of the int type. Two data records are inserted. Assume that the sum of the values of the two data records must be less than or equal to 10 in the service logic of table a. Two transactions are concurrently started. The values are updated and modified based on the read values. After the modification, the sum of values is less than or equal to 10 in the transactions. After the modification is committed, the sum of values is 12, which violates the assumed service logic of table a.
gaussdb=# create table a(id int, value int); CREATE TABLE gaussdb=# insert into a values(1,4); INSERT 0 1 gaussdb=# insert into a values(2,4); INSERT 0 1 session1 : gaussdb=# start transaction isolation level repeatable read; START TRANSACTION gaussdb=# select * from a; id | value ----+------- 1 | 4 2 | 4 (2 rows) gaussdb=# update a set value = 6 where id = 1; UPDATE 1 gaussdb=# select * from a; id | value ----+------- 1 | 6 2 | 4 (2 rows) session2: gaussdb=# start transaction isolation level repeatable read; START TRANSACTION gaussdb=# select * from a; id | value ----+------- 1 | 4 2 | 4 (2 rows) gaussdb=# update a set value = 6 where id = 2; UPDATE 1 gaussdb=# select * from a; id | value ----+------- 1 | 4 2 | 6 (2 rows) session1: gaussdb=# commit; COMMIT session2: gaussdb=# commit; COMMIT gaussdb=# select * from a; id | value ----+------- 1 | 6 2 | 6 (2 rows)
Scenario 2: Table a has the id and value columns of the int type. The id is the primary key. When the primary key is deleted and inserted concurrently, the values of two primary keys may be read in the transaction, violating the primary key constraint.
gaussdb=# create table a(id int primary key, value int); NOTICE: CREATE TABLE / PRIMARY KEY will create implicit index "a_pkey" for table "a" CREATE TABLE gaussdb=# insert into a values(1,10); INSERT 0 1 session1: gaussdb=# start transaction isolation level repeatable read; START TRANSACTION gaussdb=# delete a where id = 1; DELETE 1 session2: gaussdb=# start transaction isolation level repeatable read; START TRANSACTION gaussdb=# select * from a; id | value ----+------- 1 | 10 (1 row) session1: gaussdb=# commit; COMMIT session2: gaussdb=# insert into a values(1, 100); INSERT 0 1 gaussdb=# select * from a; id | value ----+------- 1 | 10 1 | 100 (2 rows)
Feedback
Was this page helpful?
Provide feedbackThank you very much for your feedback. We will continue working to improve the documentation.See the reply and handling status in My Cloud VOC.
For any further questions, feel free to contact us through the chatbot.
Chatbot