Help Center/ GaussDB/ Centralized_3.x/ Autonomous Transaction/ Stored Procedure Supporting Autonomous Transaction
Updated on 2024-05-07 GMT+08:00

Stored Procedure Supporting Autonomous Transaction

An autonomous transaction can be defined in a stored procedure. 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. 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 that contains an autonomous transaction.
gaussdb=# CREATE OR REPLACE 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); 
	dbe_output.print_line('just use call.');
END;
/
CREATE PROCEDURE
-- Create a common stored procedure that calls an autonomous transaction stored procedure.
gaussdb=# CREATE OR REPLACE PROCEDURE autonomous_5(a int, b int)  AS 
DECLARE 
BEGIN
	dbe_output.print_line('just no use call.');
	insert into t2 values(666, 666);
	autonomous_4(a,b);
	rollback;
END;
/
CREATE PROCEDURE
-- Call a common stored procedure.
gaussdb=# select autonomous_5(11,22);
just no use call.
just use call.
 autonomous_5
--------------

(1 row)

-- View the table result.
gaussdb=# select * from t2 order by a;
 a  | b
----+----
  1 |  2
 11 | 22
(2 rows)

In the preceding example, a stored procedure containing an autonomous transaction is finally executed in a transaction block to be 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 the autonomous transaction.