Pragma Autonomous transaction

Pragma Autonomous transaction
--============================================================


There are five types of PRAGMA in oracle PL SQL:-

2.       PRAGMA EXCEPTION_INIT:
3.       PRAGMA SERIALLY_REUSABLE: 
4.       PRAGMA RESTRICT_REFERENCES:   -- Not Active after 11g
5.       PRAGMA INLINE



--==================================================
Autonomous Transaction:-
--==================================================
Autonomous Transaction provides a functionality to the developer
in which it allows to do changes in a separate transaction and to save/discard that particular transaction without affecting the main session transaction.

NOTE:-
1. The child code runs independently (This autonomous transaction can be specified at subprogram level) of its parent.
2. To make any subprogram to work in a different transaction, the keyword 'PRAGMA AUTONOMOUS_TRANSATION' should be given in the declarative section of that block.
3. The child code can commit or rollback & parent resumes.
It will instruct that compiler to treat this as the separate transaction and saving/discarding inside this block will not reflect in the main transaction.
4. Issuing COMMIT or ROLLBACK is mandatory before going out of this autonomous transaction to the main transaction because at any time only one transaction can be active. So once we made an autonomous transaction we need to save it and complete the transaction then only we can move back to the main transaction.
5. The parent code can continue without affecting child work.


Syntax:

DECLARE
PRAGMA AUTONOMOUS_TRANSACTION;
BEGIN
<executin_part>
[COMMIT|ROLLBACK]
END;

Ex:-

Example:-

1. Seller order booking with any other app.
2. Log Printing for debuging the big code .
3. Normal senerio

@@@@@@@@@@@@@@@@  Example :- 1 @@@@@@@@@@@@@@@@

CREATE TABLE XXSD_BIG_SELLER_INV_DETAIL_TL (
  BIG_SELLER_ID           NUMBER       NOT NULL,
  TOTAL_PRODUCT  NUMBER       NOT NULL,
  REMAINING_PRODUCT  NUMBER  
)

drop TABLE XXSD_BIG_SELLER_INV_DETAIL_TL

select * from XXSD_BIG_SELLER_INV_DETAIL_TL

insert into XXSD_BIG_SELLER_INV_DETAIL_TL values ( '99901' , 100, 100);

COMMIT;

--=============================

CREATE TABLE XXSD_SELLER_ORDER_DETAIL_TL (
  SELLER_ID           NUMBER       NOT NULL,
  ORDER_NO  VARCHAR2(50) NOT NULL,
  QTY NUMBER,
  DELIVERED_FLAG  VARCHAR2(50) NOT NULL,
  AMOUNT  NUMBER       NOT NULL,
  DESCRIPTION VARCHAR2(50) NOT NULL,
  Order_Date DATE
)


DROP TABLE XXSD_SELLER_ORDER_DETAIL_TL

--=============================

CREATE OR REPLACE PROCEDURE XX_ORDER_INFO (
P_SELLER_ID   IN  NUMBER,
P_ORDER_NO IN VARCHAR2,
P_QTY IN NUMBER,
P_DELIVERED_FLAG IN VARCHAR2,
P_AMOUNT   IN  NUMBER ,
P_DESCRIPTION   IN  VARCHAR2) AS

  PRAGMA AUTONOMOUS_TRANSACTION;
 
BEGIN
 
    INSERT INTO XXSD_SELLER_ORDER_DETAIL_TL (SELLER_ID, ORDER_NO, QTY,  DELIVERED_FLAG,  AMOUNT, DESCRIPTION, Order_Date)  
    VALUES (P_SELLER_ID, P_ORDER_NO , P_QTY, P_DELIVERED_FLAG, P_AMOUNT, P_DESCRIPTION, sysdate);
 
    COMMIT;
END;

--=============================

DECLARE

CURSOR C1 IS

--select '2001' SELLER_ID,  'S2-Order-1' ORDER_NO, '1' QTY, 'Y' DELIVERED_FLAG, '100'  AMOUNT, 'Order Placed'  DESCRIPTION, sysdate Order_Date from dual
select '2001' SELLER_ID,  'S2-Order-2' ORDER_NO, '1' QTY,  'N' DELIVERED_FLAG, '10'  AMOUNT, 'Order Placed'  DESCRIPTION, sysdate Order_Date from dual
;

BEGIN

    FOR I IN C1 LOOP
     
    UPDATE XXSD_BIG_SELLER_INV_DETAIL_TL
    set REMAINING_PRODUCT = REMAINING_PRODUCT- I.QTY;
       
    XX_ORDER_INFO (I.SELLER_ID, I.ORDER_NO, I.QTY, I.DELIVERED_FLAG,  I.AMOUNT, I.DESCRIPTION);        
     
        IF  I.DELIVERED_FLAG = 'N' THEN
        ROLLBACK;
        ELSE
        COMMIT;
        END IF;
       
    END LOOP;

COMMIT;
EXCEPTION WHEN OTHERS THEN 
    ROLLBACK;
END;

--=============================
Check:-

select * from XXSD_BIG_SELLER_INV_DETAIL_TL

select * from XXSD_SELLER_ORDER_DETAIL_TL


@@@@@@@@@@@@@@@@  Example :- 2 @@@@@@@@@@@@@@@@

CREATE SEQUENCE ERROR_LOGS_SEQ

DROP SEQUENCE ERROR_LOGS_SEQ

--=============================
CREATE TABLE XXSD_SELLER_ORDER_DETAIL_TL (
  SELLER_ID           NUMBER       NOT NULL,
  AMOUNT  NUMBER       NOT NULL,
  DESCRIPTION VARCHAR2(50) NOT NULL,
  Order_Date DATE
)


DROP TABLE XXSD_SELLER_ORDER_DETAIL_TL

--=============================

CREATE TABLE XX_ERROR_LOG_TL
(
  id             NUMBER(10)     NOT NULL,
  log_timestamp  TIMESTAMP      NOT NULL,
  Line_No   VARCHAR2(100),
  Object_name  VARCHAR2(100),
  error_Code  VARCHAR2(100),
  error_message  VARCHAR2(4000),
  CONSTRAINT error_logs_pk PRIMARY KEY (id)
)

drop TABLE XX_ERROR_LOG_TL

--=============================

CREATE OR REPLACE PROCEDURE XX_ERROR_LOG_PRINTER (
P_Line_No   IN  VARCHAR2,
P_Object_name   IN  VARCHAR2 ,
P_error_Code   IN  VARCHAR2,
p_error_message  IN  VARCHAR2) AS

PRAGMA AUTONOMOUS_TRANSACTION;

BEGIN
 
  INSERT INTO XX_ERROR_LOG_TL (id, log_timestamp, Line_No, Object_name  ,error_Code  ,error_message)
  VALUES (error_logs_seq.NEXTVAL, SYSTIMESTAMP,P_Line_No, P_Object_name  ,P_error_Code, p_error_message);
 
  COMMIT;
END;

--=============================

DECLARE
V_Line_No NUMBER:=0;
V_Object_name VARCHAR2(100):= 'AUTONOMOUS BLOCK';
BEGIN
--Code line no 1 ---
V_Line_No:=1;
  INSERT INTO XXSD_SELLER_ORDER_DETAIL_TL (CUSTOMER_id, AMOUNT, DESCRIPTION, Order_Date)   VALUES (101, 10, 'Order Placed', sysdate);

--Code line no 2 ---
V_Line_No:=2;
  INSERT INTO XXSD_SELLER_ORDER_DETAIL_TL (CUSTOMER_id, AMOUNT, DESCRIPTION, Order_Date)   VALUES (102, NULL, 'Order Placed', sysdate);

--Code line no 3 ---
V_Line_No:=3;
  INSERT INTO XXSD_SELLER_ORDER_DETAIL_TL (CUSTOMER_id, AMOUNT, DESCRIPTION, Order_Date)   VALUES (103, 80, 'Order Placed', sysdate);

--Code line no 4 ---
V_Line_No:=4;
  INSERT INTO XXSD_SELLER_ORDER_DETAIL_TL (CUSTOMER_id, AMOUNT, DESCRIPTION, Order_Date)   VALUES (104, 100, 'Order Placed', sysdate);

--Code line no 5 ---
V_Line_No:=5;
  INSERT INTO XXSD_SELLER_ORDER_DETAIL_TL (CUSTOMER_id, AMOUNT, DESCRIPTION, Order_Date)   VALUES (105, 102, 'Order Placed', sysdate);

COMMIT;
EXCEPTION
  WHEN OTHERS THEN
  XX_ERROR_LOG_PRINTER (V_Line_No, V_Object_name, SQLCODE, SQLERRM);    
    ROLLBACK;
END;

--=============================
Check:-
select * from XX_ERROR_LOG_TL

select * from XXSD_SELLER_ORDER_DETAIL_TL


@@@@@@@@@@@@@@@@  Example :- 3 @@@@@@@@@@@@@@@@

--=============================
declare
BEGIN   
INSERT INTO  XXSD.XXSD_AUDIT_DATA (COLUMN1) vALUES(SYSDATE);
XXSD_ERROR;   
ROLLBACK;
EXCEPTION WHEN OTHERS THEN   ROLLBACK;
end
;

 CREATE OR REPLACE PROCEDURE XXSD_ERROR
    IS
PRAGMA AUTONOMOUS_TRANSACTION;
    BEGIN
    INSERT INTO XXSD_TEST (A) VALUES ( SYSDATE);
    COMMIT;
    EXCEPTION WHEN OTHERS THEN   ROLLBACK;
    END;  

--=============================

Comments

Popular posts from this blog

E-Text Report In Fusion | Types of E-Text reports

Supplier API's

How to pass default Parameter in cursor