Hi,
The best way to track the oracle errors is throug it's ORACLE Error log files. However, we do have one more manual mechanism to track all those ERROR Messages in Database using "SERVERERROR" DDL Triggers.
Please find the below steps to achieve this.
Step 1
======
SQL> GRANT ADMINISTER DATABASE TRIGGER TO <USERNAME>;
Step 2
======
create table oraerror (
id NUMBER,
log_date DATE,
log_usr VARCHAR2(30),
terminal VARCHAR2(50),
err_nr NUMBER(10),
err_msg VARCHAR2(4000),
stmt VARCHAR2(4000)
);
Step 3
======
create sequence oraerror_seq
start with 1
increment by 1
minvalue 1
nomaxvalue
nocache
nocycle;
Step 4
======
CREATE OR REPLACE TRIGGER after_error
AFTER SERVERERROR ON DATABASE
DECLARE
pragma autonomous_transaction;
id NUMBER;
sql_text ORA_NAME_LIST_T;
v_stmt VARCHAR2(4000);
n NUMBER;
BEGIN
SELECT oraerror_seq.nextval INTO id FROM dual;
n := ora_sql_txt(sql_text);
IF n >= 1
THEN
FOR i IN 1..n LOOP
v_stmt := v_stmt || sql_text(i);
END LOOP;
END IF;
FOR n IN 1..ora_server_error_depth LOOP
INSERT INTO oraerror VALUES (id, sysdate, ora_login_user, ora_client_ip_address, ora_server_error(n), ora_server_error_msg(n), v_stmt);
COMMIT;
END LOOP;
--
END after_error;
Test Case
=========
SQL> CREATE TABLE TESTING(T INT);
Table created.
SQL> SELECT FROM TESTING;
SELECT FROM TESTING
*
ERROR at line 1:
ORA-00936: missing expression
SQL> SELECT * FROM ORAERROR;
ID LOG_DATE LOG_USR
---------- --------- ------------------------------
TERMINAL ERR_NR
-------------------------------------------------- ----------
ERR_MSG
--------------------------------------------------------------------------------
STMT
--------------------------------------------------------------------------------
1 23-JUL-12 SCOTT
936
ORA-00936: missing expression
SELECT FROM TESTING
--Dinesh
Comments
Post a Comment