Transaction Statements
A stored procedure itself is automatically in a transaction. A transaction is automatically started when the most peripheral stored procedure is called. In addition, the transaction is automatically committed when the calling ends, or is rolled back when an exception occurs during calling. In addition to automatic transaction control, you can also use COMMIT/ROLLBACK to control transactions in stored procedures. Running the COMMIT/ROLLBACK commands in a stored procedure will commit or roll back the current transaction and automatically starts a new transaction. All subsequent operations will be performed in the new transaction.
A savepoint is a special mark inside a transaction. It allows all commands that are executed after it was established to be rolled back, restoring the transaction state to what it was at the time of the savepoint. In a stored procedure, you can use savepoints to manage transactions. Currently, you can create, roll back, and release savepoints. If a savepoint for rollback is used in a stored procedure, only the modification of the current transaction is rolled back. The execution process of the stored procedure is not changed, and the values of local variables in the stored procedure are not rolled back.
The applicable contexts are as follows:
- COMMIT, ROLLBACK, and SAVEPOINT can be used in PL/SQL stored procedures/functions.
- COMMIT, ROLLBACK, and SAVEPOINT can be used in stored procedures and functions that contain EXCEPTION.
- COMMIT, ROLLBACK, and SAVEPOINT can be used in EXCEPTION statements of stored procedures.
- A stored procedure that contains COMMIT, ROLLBACK, or SAVEPOINT (which means the stored procedure is controlled by BEGIN, START, or END) can be called in a transaction block.
- A stored procedure that contains savepoints can be invoked in a subtransaction and an externally defined savepoint is used to roll back the transaction to the savepoint defined outside the stored procedure.
- A savepoint defined in the stored procedure can be viewed outside the stored procedure. That is, the modification of the transaction can be rolled back to the savepoint defined in the stored procedure.
- COMMIT, ROLLBACK, and SAVEPOINT, as well as IF, FOR, CURSOR LOOP, and WHILE, can be called in most PL/SQL contexts and statements.
The following content can be submitted or rolled back:
- DDL statements after COMMIT or ROLLBACK can be submitted or rolled back.
- DML statements after COMMIT or ROLLBACK can be submitted.
- GUC parameters in stored procedures can be submitted or rolled back.
Syntax
Define a savepoint. SAVEPOINT savepoint_name; Roll back a savepoint. ROLLBACK TO [SAVEPOINT] savepoint_name; Release a savepoint. RELEASE [SAVEPOINT] savepoint_name;
Examples
COMMIT/ROLLBACK can be used in PL/SQL stored procedures.
CREATE TABLE EXAMPLE1(COL1 INT); CREATE OR REPLACE PROCEDURE TRANSACTION_EXAMPLE() AS BEGIN FOR i IN 0..20 LOOP INSERT INTO EXAMPLE1(COL1) VALUES (i); IF i % 2 = 0 THEN COMMIT; ELSE ROLLBACK; END IF; END LOOP; END; /
- COMMIT and ROLLBACK can be used in stored procedures that contain EXCEPTION.
- COMMIT and ROLLBACK can be used in EXCEPTION statements of stored procedures.
- DDL statements after COMMIT or ROLLBACK can be submitted or rolled back.
CREATE OR REPLACE PROCEDURE TEST_COMMIT_INSERT_EXCEPTION_ROLLBACK() AS BEGIN DROP TABLE IF EXISTS TEST_COMMIT; CREATE TABLE TEST_COMMIT(A INT, B INT); INSERT INTO TEST_COMMIT SELECT 1, 1; COMMIT; CREATE TABLE TEST_ROLLBACK(A INT, B INT); RAISE EXCEPTION 'RAISE EXCEPTION AFTER COMMIT'; EXCEPTION WHEN OTHERS THEN INSERT INTO TEST_COMMIT SELECT 2, 2; ROLLBACK; END; /
A stored procedure that contains COMMIT or ROLLBACK (which means the stored procedure is controlled by BEGIN, START, or END) can be called in a transaction block.
BEGIN; CALL TEST_COMMIT_INSERT_EXCEPTION_ROLLBACK(); END;
COMMIT and ROLLBACK, as well as IF, FOR, CURSOR LOOP, and WHILE, can be called in most PL/SQL contexts and statements.
CREATE OR REPLACE PROCEDURE TEST_COMMIT2() IS BEGIN DROP TABLE IF EXISTS TEST_COMMIT; CREATE TABLE TEST_COMMIT(A INT); FOR I IN REVERSE 3..0 LOOP INSERT INTO TEST_COMMIT SELECT I; COMMIT; END LOOP; FOR I IN REVERSE 2..4 LOOP UPDATE TEST_COMMIT SET A=I; COMMIT; END LOOP; EXCEPTION WHEN OTHERS THEN INSERT INTO TEST_COMMIT SELECT 4; COMMIT; END; /
GUC parameters in stored procedures can be submitted or rolled back.
SHOW explain_perf_mode; SHOW enable_force_vector_engine; CREATE OR REPLACE PROCEDURE GUC_ROLLBACK() AS BEGIN SET enable_force_vector_engine = on; COMMIT; SET explain_perf_mode TO pretty; ROLLBACK; END; / call GUC_ROLLBACK(); guc_rollback -------------- (1 row) SHOW explain_perf_mode; explain_perf_mode ------------------- normal (1 row) SHOW enable_force_vector_engine; enable_force_vector_engine ---------------------------- on (1 row) SET enable_force_vector_engine = off;
Savepoints can be used in PL/SQL stored procedures to roll back partial transaction modifications.
CREATE OR REPLACE PROCEDURE STP_SAVEPOINT_EXAMPLE1() AS BEGIN INSERT INTO EXAMPLE1 VALUES(1); SAVEPOINT s1; INSERT INTO EXAMPLE1 VALUES(2); ROLLBACK TO s1; -- Roll back the insertion of record 2. INSERT INTO EXAMPLE1 VALUES(3); END; /
You can use a savepoint in a PL/SQL stored procedure to roll back to a savepoint defined outside the stored procedure.
CREATE OR REPLACE PROCEDURE STP_SAVEPOINT_EXAMPLE2() AS BEGIN INSERT INTO EXAMPLE1 VALUES(2); ROLLBACK TO s1; -- Roll back the insertion of record 2. INSERT INTO EXAMPLE1 VALUES(3); END; / BEGIN; INSERT INTO EXAMPLE1 VALUES(1); SAVEPOINT s1; CALL STP_SAVEPOINT_EXAMPLE2(); stp_savepoint_example2 ------------------------ (1 row) SELECT * FROM EXAMPLE1; col1 ------ 0 4 10 14 16 18 20 3 3 3 2 6 8 12 1 1 (16 rows) COMMIT;
You can use a savepoint defined outside the stored procedure to roll back to a savepoint in a PL/SQL stored procedure.
CREATE OR REPLACE PROCEDURE STP_SAVEPOINT_EXAMPLE3() AS BEGIN INSERT INTO EXAMPLE1 VALUES(1); SAVEPOINT s1; INSERT INTO EXAMPLE1 VALUES(2); END; / BEGIN; INSERT INTO EXAMPLE1 VALUES(3); CALL STP_SAVEPOINT_EXAMPLE3(); stp_savepoint_example3 ------------------------ (1 row) ROLLBACK TO SAVEPOINT s1; -- Roll back the insertion of record 2 to the stored procedure. SELECT * FROM EXAMPLE1; col1 ------ 0 4 10 14 16 18 20 3 3 3 3 2 6 8 12 1 1 1 (18 rows) COMMIT;
The COMMIT and ROLLBACK statements can be invoked in a function.
CREATE OR REPLACE FUNCTION FUNCTION_EXAMPLE1() RETURN INT AS EXP INT; BEGIN FOR i IN 0..20 LOOP INSERT INTO EXAMPLE1(col1) VALUES (i); IF i % 2 = 0 THEN COMMIT; ELSE ROLLBACK; END IF; END LOOP; SELECT COUNT(*) FROM EXAMPLE1 INTO EXP; RETURN EXP; END; /
Constraints
- The unapplicable contexts are as follows:
- COMMIT, ROLLBACK, and SAVEPOINT cannot be called in stored procedures other than PL/SQL, such as PL/Java and PL/Python.
- After SAVEPOINT is called in a transaction block, stored procedures that contain COMMIT/ROLLBACK cannot be called.
- Stored procedures that contain COMMIT, ROLLBACK, or SAVEPOINT cannot be called in TRIGGER.
- COMMIT, ROLLBACK, and SAVEPOINT cannot be invoked in EXECUTE statements.
- Stored procedures that contain COMMIT, ROLLBACK, or SAVEPOINT cannot be called in CURSOR statements.
- Stored procedures that contain IMMUTABLE or SHIPPABLE cannot call COMMIT, ROLLBACK, SAVEPOINT or another stored procedure that contain COMMIT, ROLLBACK, or SAVEPOINT.
- Stored procedures that contain COMMIT, ROLLBACK, or SAVEPOINT cannot be called in SQL statements other than SELECT PROC and CALL PROC.
- COMMIT, ROLLBACK, or SAVEPOINT cannot be called in a stored procedure whose header contains GUC parameters.
- COMMIT, ROLLBACK, or SAVEPOINT cannot be called in expressions or CURSOR and EXECUTE statements.
- Stored procedures that contain COMMIT, ROLLBACK, or SAVEPOINT cannot be called in the return values and expression calculation of stored procedures.
- Savepoints defined outside a stored procedure cannot be released in the stored procedure.
- A stored procedure transaction and its autonomous transaction are two independent transactions and cannot use savepoints defined in each other's transaction.
- Advanced packages cannot call stored procedures that contain COMMIT, ROLLBACK, or SAVEPOINT statements through DBE_SQL.
- The following content cannot be committed or rolled back:
- Variables declared or imported in stored procedures cannot be committed or rolled back.
- In stored procedures, GUC parameters that take effect only after a restart cannot be submitted or rolled back.
There are the following constraints on the use of COMMIT/ROLLBACK in a stored procedure:
A TRIGGER stored procedure cannot contain COMMIT/ROLLBACK or called another stored procedure that contains COMMIT/ROLLBACK.
CREATE OR REPLACE FUNCTION FUNCTION_TRI_EXAMPLE2() RETURN TRIGGER AS EXP INT; BEGIN FOR i IN 0..20 LOOP INSERT INTO EXAMPLE1(col1) VALUES (i); IF i % 2 = 0 THEN COMMIT; ELSE ROLLBACK; END IF; END LOOP; SELECT COUNT(*) FROM EXAMPLE1 INTO EXP; END; / CREATE TRIGGER TRIGGER_EXAMPLE AFTER DELETE ON EXAMPLE1 FOR EACH ROW EXECUTE PROCEDURE FUNCTION_TRI_EXAMPLE2(); DELETE FROM EXAMPLE1; ERROR: Can not commit/rollback if it's atomic is true: can not use commit rollback in Complex SQL CONTEXT: PL/pgSQL function function_tri_example2() line 7 at COMMIT
Stored procedures that contain IMMUTABLE or SHIPPABLE cannot call COMMIT/ROLLBACK or another stored procedure that contains COMMIT/ROLLBACK.
CREATE OR REPLACE PROCEDURE TRANSACTION_EXAMPLE1() IMMUTABLE AS BEGIN FOR i IN 0..20 LOOP INSERT INTO EXAMPLE1 (col1) VALUES (i); IF i % 2 = 0 THEN COMMIT; ELSE ROLLBACK; END IF; END LOOP; END; / CALL TRANSACTION_EXAMPLE1(); ERROR: Can not commit/rollback if it's atomic is true: commit/rollback/savepoint is not allowed in a non-volatile function CONTEXT: PL/pgSQL function transaction_example1() line 7 at COMMIT
Variables declared or imported in stored procedures cannot be committed or rolled back.
CREATE OR REPLACE PROCEDURE TRANSACTION_EXAMPLE2(EXP_OUT OUT INT) AS EXP INT; BEGIN EXP_OUT := 0; COMMIT; DBE_OUTPUT.PRINT_LINE('EXP IS:'||EXP); EXP_OUT := 1; ROLLBACK; DBE_OUTPUT.PRINT_LINE('EXP IS:'||EXP); END; /
Calling in SQL statements (other than Select Procedure) is not supported.
CREATE OR REPLACE PROCEDURE TRANSACTION_EXAMPLE3() AS BEGIN FOR i IN 0..20 LOOP INSERT INTO EXAMPLE1 (col1) VALUES (i); IF i % 2 = 0 THEN EXECUTE IMMEDIATE 'COMMIT'; ELSE EXECUTE IMMEDIATE 'ROLLBACK'; END IF; END LOOP; END; / CALL TRANSACTION_EXAMPLE2(100); EXP IS: EXP IS: exp_out --------- 1 (1 row)
COMMIT/ROLLBACK cannot be called in a stored procedure whose header contains GUC parameters.
CREATE OR REPLACE PROCEDURE TRANSACTION_EXAMPLE4() SET ARRAY_NULLS TO "ON" AS BEGIN FOR i IN 0..20 LOOP INSERT INTO EXAMPLE1 (col1) VALUES (i); IF i % 2 = 0 THEN COMMIT; ELSE ROLLBACK; END IF; END LOOP; END; / CALL TRANSACTION_EXAMPLE4(); ERROR: Can not commit/rollback if it's atomic is true: transaction statement in store procedure with GUC setting in option clause is not supported CONTEXT: PL/pgSQL function transaction_example4() line 6 at COMMIT
A stored procedure object whose cursor is open cannot contain COMMIT/ROLLBACK.
CREATE OR REPLACE PROCEDURE TRANSACTION_EXAMPLE5(INTIN IN INT, INTOUT OUT INT) AS BEGIN INTOUT := INTIN + 1; COMMIT; END; / CREATE OR REPLACE PROCEDURE TRANSACTION_EXAMPLE6() AS CURSOR CURSOR1(EXPIN INT) IS SELECT TRANSACTION_EXAMPLE5(EXPIN); INTEXP INT; BEGIN FOR i IN 0..20 LOOP OPEN CURSOR1(i); FETCH CURSOR1 INTO INTEXP; INSERT INTO EXAMPLE1(COL1) VALUES (INTEXP); IF i % 2 = 0 THEN COMMIT; ELSE ROLLBACK; END IF; CLOSE CURSOR1; END LOOP; END; / CALL TRANSACTION_EXAMPLE6(); ERROR: Can not commit/rollback if it's atomic is true: transaction statement in store procedure used as cursor is not supported CONTEXT: PL/pgSQL function transaction_example5(integer) line 4 at COMMIT referenced column: transaction_example5 PL/pgSQL function transaction_example6() line 8 at FETCH
COMMIT or ROLLBACK cannot be called in expressions or CURSOR and EXECUTE statements.
CREATE OR REPLACE PROCEDURE exec_func1() AS BEGIN CREATE TABLE TEST_exec(A INT); COMMIT; END; / CREATE OR REPLACE PROCEDURE exec_func2() AS BEGIN EXECUTE exec_func1(); COMMIT; END; / CALL exec_func2(); NOTICE: The 'DISTRIBUTE BY' clause is not specified. Using 'a' as the distribution column by default. HINT: Please use 'DISTRIBUTE BY' clause to specify suitable data distribution column. CONTEXT: SQL statement "CREATE TABLE TEST_exec(A INT)" PL/pgSQL function exec_func1() line 3 at SQL statement PL/pgSQL function exec_func2() line 3 at EXECUTE statement ERROR: Can not commit/rollback if it's atomic is true: transaction statement in store procedure used as a expression is not supported CONTEXT: PL/pgSQL function exec_func1() line 4 at COMMIT PL/pgSQL function exec_func2() line 3 at EXECUTE statement
Return values and expression calculation of stored procedures are not supported.
CREATE OR REPLACE PROCEDURE exec_func3(RET_NUM OUT INT) AS BEGIN RET_NUM := 1+1; COMMIT; END; / CREATE OR REPLACE PROCEDURE exec_func4(ADD_NUM IN INT) AS SUM_NUM INT; BEGIN SUM_NUM := ADD_NUM + exec_func3(); COMMIT; END; / CALL exec_func4(1); ERROR: Can not commit/rollback if it's atomic is true: transaction statement in store procedure used as a expression is not supported CONTEXT: PL/pgSQL function exec_func3() line 4 at COMMIT PL/pgSQL function exec_func4(integer) line 4 at assignment
Savepoints defined outside a stored procedure cannot be released in the stored procedure.
CREATE OR REPLACE PROCEDURE STP_SAVEPOINT_EXAMPLE3() AS BEGIN INSERT INTO EXAMPLE1 VALUES(2); RELEASE SAVEPOINT s1; -- Release the savepoint defined outside the stored procedure. INSERT INTO EXAMPLE1 VALUES(3); END; / BEGIN; INSERT INTO EXAMPLE1 VALUES(1); SAVEPOINT s1; CALL STP_SAVEPOINT_EXAMPLE3(); COMMIT; ERROR: cannot release outer savepoint CONTEXT: PL/pgSQL function stp_savepoint_example3() line 4 at RELEASE SAVEPOINT
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