Package Supporting Autonomous Transaction
An autonomous transaction can be defined in a stored procedure or function in a package. The identifier of an autonomous transaction is PRAGMA AUTONOMOUS_TRANSACTION. The syntax of an autonomous transaction is the same as that of creating a stored procedure or function in a package. For details, see CREATE PACKAGE. The following is an example.
-- Create a table. gaussdb=# CREATE TABLE t2(a INT, b INT); CREATE TABLE gaussdb=# INSERT INTO t2 VALUES(1,2); INSERT 0 1 gaussdb=# SELECT * FROM t2; a | b ---+--- 1 | 2 (1 row) -- Create a stored procedure or function in a package that contains autonomous transactions. gaussdb=# CREATE OR REPLACE PACKAGE autonomous_pkg AS PROCEDURE autonomous_4(a INT, b INT); FUNCTION autonomous_32(a INT ,b INT) RETURN INT; END autonomous_pkg; / CREATE PACKAGE gaussdb=# CREATE OR REPLACE PACKAGE BODY autonomous_pkg AS PROCEDURE autonomous_4(a INT, b INT) AS DECLARE num3 INT := a; num4 INT := b; PRAGMA AUTONOMOUS_TRANSACTION; BEGIN INSERT INTO t2 VALUES(num3, num4); END; FUNCTION autonomous_32(a INT ,b INT) RETURN INT AS DECLARE PRAGMA AUTONOMOUS_TRANSACTION; BEGIN INSERT INTO t2 VALUES(a, b); RETURN 1; END; END autonomous_pkg; / CREATE PACKAGE BODY -- Create a common stored procedure that calls a stored procedure or function from a package that contains autonomous transactions. gaussdb=# CREATE OR REPLACE PROCEDURE autonomous_5(a INT, b INT) AS DECLARE va INT; BEGIN INSERT INTO t2 VALUES(666, 666); autonomous_pkg.autonomous_4(a,b); va := autonomous_pkg.autonomous_32(a + 1, b + 1); ROLLBACK; END; / CREATE PROCEDURE -- Call a common stored procedure. gaussdb=# SELECT autonomous_5(11,22); autonomous_5 -------------- (1 row) -- View the table result. gaussdb=# SELECT * FROM t2 ORDER BY a; a | b ----+---- 1 | 2 11 | 22 12 | 23 (3 rows) gaussdb=# DROP TABLE t2; DROP TABLE
In the preceding example, a stored procedure or function in a package containing autonomous transactions is finally executed in a transaction block that is rolled back, which directly illustrates a characteristic of the autonomous transaction, that is, rollback of the primary transaction does not affect content that has been committed by an autonomous transaction.
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