Updated on 2024-05-07 GMT+08:00
Restrictions
- When an autonomous transaction is executed, an autonomous transaction session is started in the background. You can use max_concurrent_autonomous_transactions to set the maximum number of concurrent autonomous transactions. The value range is 0 to 10000, and the default value is 10.
- When max_concurrent_autonomous_transactions is set to 0, autonomous transactions cannot be executed.
- After a new session is started for an autonomous transaction, the default session parameters are used and objects (including session-level variables, local temporary variables, and global temporary table data) of the primary session are not shared.
- Theoretically, the upper limit of autonomous transactions is 10000. Actually, the upper limit is a dynamic value. For details, see the description of the GUC parameter max_concurrent_autonomous_transactions.
- Autonomous transactions are affected by the communication buffer. The size of the information returned to the client is limited by the length of the communication buffer. If the size exceeds the length of the communication buffer, an error is reported.
- A trigger function does not support autonomous transactions.
gaussdb=# CREATE TABLE test_trigger_des_tbl(id1 INT, id2 INT, id3 INT); CREATE TABLE gaussdb=# CREATE OR REPLACE FUNCTION tri_insert_func() RETURNS TRIGGER AS $$ DECLARE PRAGMA AUTONOMOUS_TRANSACTION; BEGIN INSERT INTO test_trigger_des_tbl VALUES(NEW.id1, NEW.id2, NEW.id3); RETURN NEW; END $$ LANGUAGE plpgsql; ERROR: Triggers do not support autonomous transactions DETAIL: N/A CONTEXT: compilation of PL/pgSQL function "tri_insert_func" near line 4
- Autonomous transactions cannot be called by non-top-layer anonymous blocks (but can only be called by top-layer autonomous transactions, including stored procedures, functions, and anonymous blocks).
gaussdb=# drop table if exists t1; gaussdb=# create table t1(a int ,b text); CREATE TABLE gaussdb=# DECLARE --PRAGMA AUTONOMOUS_TRANSACTION; BEGIN DECLARE PRAGMA AUTONOMOUS_TRANSACTION; BEGIN dbe_output.print_line('just use call.'); insert into t1 values(1,'can you rollback!'); END; insert into t1 values(2,'I will rollback!'); rollback; END; / just use call. ANONYMOUS BLOCK EXECUTE gaussdb=# select * from t1; a | b ---+--- (0 rows)
- In an autonomous transaction, the ref cursor parameter can be passed only through the PROCEDURE OUT parameter. The ref cursor parameter cannot be passed through the IN, INOUT, or FUNCTION parameter.
gaussdb=# create table sections(section_ID int); CREATE TABLE gaussdb=# insert into sections values(1); INSERT 0 1 gaussdb=# insert into sections values(1); INSERT 0 1 gaussdb=# insert into sections values(1); INSERT 0 1 gaussdb=# insert into sections values(1); INSERT 0 1 1. The PROCEDURE OUT output parameter passes the ref cursor parameter (supported). gaussdb=# CREATE OR REPLACE PROCEDURE proc_sys_ref(OUT c1 refcursor) IS declare PRAGMA AUTONOMOUS_TRANSACTION; BEGIN OPEN c1 FOR SELECT section_ID FROM sections ORDER BY section_ID; END; / CREATE PROCEDURE gaussdb=# CREATE OR REPLACE PROCEDURE proc_sys_call() AS DECLARE c1 SYS_REFCURSOR; TEMP NUMBER(4); BEGIN proc_sys_ref(c1); if c1%isopen then raise notice '%','ok'; end if; LOOP FETCH C1 INTO TEMP; raise notice '%',C1%ROWCOUNT; EXIT WHEN C1%NOTFOUND; END LOOP; END; / CREATE PROCEDURE 2. The PROCEDURE IN or INOUT output parameter passes the ref cursor parameter (not supported). gaussdb=# CREATE OR REPLACE PROCEDURE proc_sys_ref(IN c1 refcursor) IS declare PRAGMA AUTONOMOUS_TRANSACTION; TEMP NUMBER(4); BEGIN if c1%isopen then raise notice '%','ok'; end if; LOOP FETCH C1 INTO TEMP; raise notice '%',C1%ROWCOUNT; EXIT WHEN C1%NOTFOUND; END LOOP; END; / CREATE PROCEDURE gaussdb=# CREATE OR REPLACE PROCEDURE proc_sys_call() AS DECLARE c1 SYS_REFCURSOR; TEMP NUMBER(4); BEGIN OPEN c1 FOR SELECT section_ID FROM sections ORDER BY section_ID; proc_sys_ref(c1); END; / CREATE PROCEDURE gaussdb=# CALL proc_sys_call(); ERROR: Unsupported: ref_cursor parameter is not supported for autonomous transactions. CONTEXT: SQL statement "CALL proc_sys_ref(c1)" PL/pgSQL function proc_sys_call() line 7 at PERFORM 3. FUNCTION RETURN passes the ref cursor parameter (not supported) gaussdb=# CREATE OR REPLACE function proc_sys_ref() return SYS_REFCURSOR IS declare PRAGMA AUTONOMOUS_TRANSACTION; C1 SYS_REFCURSOR; BEGIN OPEN C1 FOR SELECT section_ID FROM sections ORDER BY section_ID; return C1; END; / gaussdb=# DROP PROCEDURE proc_sys_ref; DROP PROCEDURE 4. The FUNCTION OUT output parameter passes the ref cursor parameter (not supported). gaussdb=# CREATE OR REPLACE function proc_sys_ref(C1 out SYS_REFCURSOR) return SYS_REFCURSOR IS declare PRAGMA AUTONOMOUS_TRANSACTION; BEGIN OPEN C1 FOR SELECT section_ID FROM sections ORDER BY section_ID; return 1; END; / ERROR: Autonomous function do not support ref cursor as return types or out, inout arguments. DETAIL: N/A CONTEXT: compilation of PL/pgSQL function "proc_sys_ref" near line 4
- The autonomous transaction function cannot directly return the record type or the out output parameter and the record type at the same time.
gaussdb=# create table test_in (id int,a date); CREATE TABLE gaussdb=# CREATE OR REPLACE FUNCTION autonomous_out() RETURNS record LANGUAGE plpgsql AS $$ DECLARE PRAGMA AUTONOMOUS_TRANSACTION; r1 record; BEGIN DBE_OUTPUT.PRINT_LINE('this is in autonomous_f_139_7'); truncate test_in; insert into test_in values (1,'1909-01-01'); select * into r1 from test_in; RETURN r1; END; $$; CREATE FUNCTION gaussdb=# select ok.id,ok.a from autonomous_out() as ok(id int,a date); ERROR: unrecognized return type for PLSQL function. gaussdb=# create type rec is (e1 integer, e2 varchar2); CREATE TYPE gaussdb=# create or replace function func(ele3 inout varchar2) return rec as i integer; ele1 rec; PRAGMA AUTONOMOUS_TRANSACTION; begin NULL; return ele1; end; / CREATE FUNCTION gaussdb=# call func(1); e1 | e2 ----+---- | (1 row)
- The isolation level of an autonomous transaction cannot be changed.
- Autonomous transactions do not support the setof return type.
gaussdb=# drop table if exists test_in; gaussdb=# create table test_in (id int,a date); CREATE TABLE gaussdb=# create table test_main (id int,a date); CREATE TABLE gaussdb=# insert into test_main values (1111,'2021-01-01'),(2222,'2021-02-02'); INSERT 0 2 gaussdb=# truncate test_in,test_main; TRUNCATE TABLE gaussdb=# CREATE OR REPLACE FUNCTION autonomous_f_022(num1 int) RETURNS SETOF test_in LANGUAGE plpgsql AS $$ DECLARE count int :=3; test_row test_in%ROWTYPE; PRAGMA AUTONOMOUS_TRANSACTION; BEGIN while true loop if count=3 then null; else if count=2 then insert into test_main values (count,'2021-03-03'); goto pos1; end if; end if; count=count-1; end loop; insert into test_main values (1000,'2021-04-04'); <<pos1>> for test_row in select * from test_main loop return next test_row; end loop; return; END; $$ ; ERROR: Autonomous transactions do not support RETURN SETOF. DETAIL: N/A CONTEXT: compilation of PL/pgSQL function "autonomous_f_022" near line 6
Parent topic: 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.
The system is busy. Please try again later.
For any further questions, feel free to contact us through the chatbot.
Chatbot