For appeals, questions and feedback about Oracle Forums, please email oracle-forums-moderators_us@oracle.com. Technical questions should be asked in the appropriate category. Thank you!
Interested in getting your voice heard by members of the Developer Marketing team at Oracle? Check out this post for AppDev or this post for AI focus group information.
CREATE OR REPLACE TRIGGER EmailOnServerErr AFTER SERVERERROR ON DATABASE DECLARE mail_conn UTL_SMTP.connection; crlf VARCHAR2(2) := chr(13)||chr(10); msg VARCHAR2(32760); sid_name VARCHAR2(16); bdump_dest VARCHAR2(128); smtp_relay VARCHAR2(32) := 'MyMailRelay'; recipient_address VARCHAR2(64) := 'recipient@MyCompany.com'; sender_address VARCHAR2(64) := 'oracle@MyCompany.com'; mail_port NUMBER := 25; log_file_handle UTL_FILE.FILE_TYPE; log_file_dir VARCHAR2(256) := 'ERR_LOG_DIR'; log_file_name VARCHAR2(256) := 'OracleErrors.log'; maxlinesize NUMBER := 32767; session_rec sys.v_$session%ROWTYPE; audit_rec sys.dba_audit_trail%ROWTYPE; auditing BOOLEAN; LinesOfSQL BINARY_INTEGER; offending_sql DBMS_STANDARD.ora_name_list_t; CURSOR bdump_cur IS SELECT TRIM(value) FROM v$parameter WHERE name = 'background_dump_dest' ; CURSOR sid_cur IS SELECT TRIM(instance_name) FROM v$instance ; CURSOR session_cur IS SELECT s.* FROM v$session s WHERE s.sid = dbms_support.mysid ; CURSOR audit_trail_cur(AUDSID IN NUMBER) IS SELECT * FROM dba_audit_trail WHERE sessionid = AUDSID ; BEGIN IF (USER = 'SYSTEM' OR USER = 'SYS') THEN -- Ignore this error NULL; ELSIF IS_SERVERERROR (1034) THEN -- Ignore this error NULL; ELSE -- get the sid OPEN sid_cur; FETCH sid_cur INTO sid_name; CLOSE sid_cur; -- get the location of the alert log OPEN bdump_cur; FETCH bdump_cur INTO bdump_dest; CLOSE bdump_cur; -- get the session information OPEN session_cur; FETCH session_cur INTO session_rec; CLOSE session_cur; -- get the audit_trail information if it exists OPEN audit_trail_cur(session_rec.audsid); FETCH audit_trail_cur INTO audit_rec; auditing := audit_trail_cur%FOUND; CLOSE audit_trail_cur; IF session_rec.program = 'MyProgram.exe' THEN NULL; -- ignore actions from MyProgram - that's where I do maintenance ELSE -- compose the message msg := 'Subject: Oracle error '||' on '||sid_name||crlf; msg := msg||'To: '||recipient_address||crlf; msg := msg||'For more information see the alert log file located at:'||crlf; msg := msg||bdump_dest||'/alert_'||sid_name||'.log'||crlf; msg := msg||'or the error log file: $'||log_file_dir||'/'||log_file_name||crlf; msg := msg||'Error Time='||TO_CHAR(SYSDATE,'DD-Mon-YYYY HH24:MI:SS')||crlf; msg := msg||DBMS_UTILITY.FORMAT_CALL_STACK||crlf; LinesOfSQL := sql_txt(offending_sql); msg := msg||'Offending SQL is:'||crlf; FOR loop_counter IN offending_sql.FIRST..offending_sql.LAST LOOP msg := msg||offending_sql(loop_counter); END LOOP; msg := msg||crlf||'----- PL/SQL Error Stack -----'||crlf; msg := msg||DBMS_UTILITY.FORMAT_ERROR_STACK||crlf; msg := msg||'V$SESSION.SADDR=' ||session_rec.saddr ||crlf; msg := msg||'V$SESSION.SID=' ||session_rec.sid ||crlf; msg := msg||'V$SESSION.SERIAL#=' ||session_rec.serial# ||crlf; msg := msg||'V$SESSION.AUDSID=' ||session_rec.audsid ||crlf; msg := msg||'V$SESSION.PADDR=' ||session_rec.paddr ||crlf; msg := msg||'V$SESSION.USER#=' ||session_rec.user# ||crlf; msg := msg||'V$SESSION.USERNAME='||session_rec.username||crlf; msg := msg||'V$SESSION.COMMAND=' ||session_rec.command ||crlf; msg := msg||'V$SESSION.OWNERID=' ||session_rec.ownerid ||crlf; msg := msg||'V$SESSION.TADDR=' ||NVL(session_rec.taddr ,'Null')||crlf; msg := msg||'V$SESSION.LOCKWAIT='||NVL(session_rec.lockwait,'Null')||crlf; msg := msg||'V$SESSION.STATUS=' ||NVL(session_rec.status ,'Null')||crlf; msg := msg||'V$SESSION.SERVER=' ||NVL(session_rec.server ,'Null')||crlf; msg := msg||'V$SESSION.SCHEMA#=' ||session_rec.schema#||crlf; msg := msg||'V$SESSION.SCHEMANAME=' ||NVL(session_rec.schemaname,'Null')||crlf; msg := msg||'V$SESSION.OSUSER=' ||NVL(session_rec.osuser ,'Null')||crlf; msg := msg||'V$SESSION.PROCESS=' ||NVL(session_rec.process ,'Null')||crlf; msg := msg||'V$SESSION.MACHINE=' ||NVL(session_rec.machine ,'Null')||crlf; msg := msg||'V$SESSION.TERMINAL=' ||NVL(session_rec.terminal ,'Null')||crlf; msg := msg||'V$SESSION.PROGRAM=' ||NVL(session_rec.program ,'Null')||crlf; msg := msg||'V$SESSION.TYPE=' ||NVL(session_rec.type ,'Null')||crlf; msg := msg||'V$SESSION.SQL_ADDRESS=' ||session_rec.sql_address ||crlf; msg := msg||'V$SESSION.SQL_HASH_VALUE=' ||NVL(TO_CHAR(session_rec.sql_hash_value) ,'Null')||crlf; msg := msg||'V$SESSION.PREV_SQL_ADDR=' ||session_rec.prev_sql_addr||crlf; msg := msg||'V$SESSION.PREV_HASH_VALUE='||NVL(TO_CHAR(session_rec.prev_hash_value),'Null')||crlf; msg := msg||'V$SESSION.MODULE=' ||NVL(session_rec.module ,'Null')||crlf; msg := msg||'V$SESSION.MODULE_HASH='||NVL(TO_CHAR(session_rec.module_hash),'Null')||crlf; msg := msg||'V$SESSION.ACTION=' ||NVL(session_rec.action ,'Null')||crlf; msg := msg||'V$SESSION.ACTION_HASH='||NVL(TO_CHAR(session_rec.action_hash),'Null')||crlf; msg := msg||'V$SESSION.CLIENT_INFO='||NVL(session_rec.client_info ,'Null')||crlf; msg := msg||'V$SESSION.FIXED_TABLE_SEQUENCE='||NVL(TO_CHAR(session_rec.fixed_table_sequence),'Null')||crlf; msg := msg||'V$SESSION.ROW_WAIT_OBJ#=' ||NVL(TO_CHAR(session_rec.row_wait_obj#) ,'Null')||crlf; msg := msg||'V$SESSION.ROW_WAIT_FILE#=' ||NVL(TO_CHAR(session_rec.row_wait_file#) ,'Null')||crlf; msg := msg||'V$SESSION.ROW_WAIT_BLOCK#='||NVL(TO_CHAR(session_rec.row_wait_block#),'Null')||crlf; msg := msg||'V$SESSION.ROW_WAIT_ROW#=' ||NVL(TO_CHAR(session_rec.row_wait_row#) ,'Null')||crlf; msg := msg||'V$SESSION.LOGON_TIME=' ||NVL(TO_CHAR(session_rec.logon_time,'DD-Mon-YYYY HH24:MI:SS'),'Null')||crlf; msg := msg||'V$SESSION.LAST_CALL_ET=' ||NVL(TO_CHAR(session_rec.last_call_et) ,'Null')||crlf; msg := msg||'V$SESSION.PDML_ENABLED=' ||NVL(session_rec.pdml_enabled ,'Null')||crlf; msg := msg||'V$SESSION.FAILOVER_TYPE=' ||NVL(session_rec.failover_type ,'Null')||crlf; msg := msg||'V$SESSION.FAILOVER_METHOD='||NVL(session_rec.failover_method,'Null')||crlf; msg := msg||'V$SESSION.FAILED_OVER=' ||NVL(session_rec.failed_over ,'Null')||crlf; msg := msg||'V$SESSION.RESOURCE_CONSUMER_GROUP='||NVL(session_rec.resource_consumer_group,'Null')||crlf; msg := msg||'V$SESSION.PDML_STATUS=' ||NVL(session_rec.pdml_status ,'Null')||crlf; msg := msg||'V$SESSION.PDDL_STATUS=' ||NVL(session_rec.pddl_status ,'Null')||crlf; msg := msg||'V$SESSION.PQ_STATUS=' ||NVL(session_rec.pq_status ,'Null')||crlf; IF auditing THEN msg := msg||'DBA_AUDIT_TRAIL.OS_USERNAME=' ||NVL(audit_rec.os_username,'Null')||crlf; msg := msg||'DBA_AUDIT_TRAIL.USERNAME=' ||NVL(audit_rec.username ,'Null')||crlf; msg := msg||'DBA_AUDIT_TRAIL.USERHOST=' ||NVL(audit_rec.userhost ,'Null')||crlf; msg := msg||'DBA_AUDIT_TRAIL.TERMINAL=' ||NVL(audit_rec.terminal ,'Null')||crlf; msg := msg||'DBA_AUDIT_TRAIL.TIMESTAMP=' ||TO_CHAR(audit_rec.timestamp,'DD-Mon-YYYY HH24:MI:SS')||crlf; msg := msg||'DBA_AUDIT_TRAIL.OWNER=' ||NVL(audit_rec.owner ,'Null')||crlf; msg := msg||'DBA_AUDIT_TRAIL.OBJ_NAME=' ||NVL(audit_rec.obj_name ,'Null')||crlf; msg := msg||'DBA_AUDIT_TRAIL.ACTION=' ||audit_rec.action ||crlf; msg := msg||'DBA_AUDIT_TRAIL.ACTION_NAME=' ||NVL(audit_rec.action_name ,'Null')||crlf; msg := msg||'DBA_AUDIT_TRAIL.NEW_OWNER=' ||NVL(audit_rec.new_owner ,'Null')||crlf; msg := msg||'DBA_AUDIT_TRAIL.NEW_NAME=' ||NVL(audit_rec.new_name ,'Null')||crlf; msg := msg||'DBA_AUDIT_TRAIL.OBJ_PRIVILEGE='||NVL(audit_rec.obj_privilege ,'Null')||crlf; msg := msg||'DBA_AUDIT_TRAIL.SYS_PRIVILEGE='||NVL(audit_rec.sys_privilege ,'Null')||crlf; msg := msg||'DBA_AUDIT_TRAIL.ADMIN_OPTION=' ||NVL(audit_rec.admin_option ,'Null')||crlf; msg := msg||'DBA_AUDIT_TRAIL.GRANTEE=' ||NVL(audit_rec.grantee ,'Null')||crlf; msg := msg||'DBA_AUDIT_TRAIL.AUDIT_OPTION=' ||NVL(audit_rec.audit_option ,'Null')||crlf; msg := msg||'DBA_AUDIT_TRAIL.SES_ACTIONS=' ||NVL(audit_rec.ses_actions ,'Null')||crlf; msg := msg||'DBA_AUDIT_TRAIL.LOGOFF_TIME=' ||NVL(TO_CHAR(audit_rec.logoff_time) ,'Null')||crlf; msg := msg||'DBA_AUDIT_TRAIL.LOGOFF_LREAD=' ||NVL(TO_CHAR(audit_rec.logoff_lread) ,'Null')||crlf; msg := msg||'DBA_AUDIT_TRAIL.LOGOFF_PREAD=' ||NVL(TO_CHAR(audit_rec.logoff_pread) ,'Null')||crlf; msg := msg||'DBA_AUDIT_TRAIL.LOGOFF_LWRITE='||NVL(TO_CHAR(audit_rec.logoff_lwrite),'Null')||crlf; msg := msg||'DBA_AUDIT_TRAIL.LOGOFF_DLOCK=' ||NVL(audit_rec.logoff_dlock ,'Null')||crlf; msg := msg||'DBA_AUDIT_TRAIL.COMMENT_TEXT=' ||NVL(audit_rec.comment_text ,'Null')||crlf; msg := msg||'DBA_AUDIT_TRAIL.SESSIONID=' ||audit_rec.sessionid ||crlf; msg := msg||'DBA_AUDIT_TRAIL.ENTRYID=' ||audit_rec.entryid ||crlf; msg := msg||'DBA_AUDIT_TRAIL.STATEMENTID=' ||audit_rec.statementid ||crlf; msg := msg||'DBA_AUDIT_TRAIL.RETURNCODE=' ||audit_rec.returncode ||crlf; msg := msg||'DBA_AUDIT_TRAIL.PRIV_USED=' ||NVL(audit_rec.priv_used,'Null')||crlf; END IF; msg := msg||'-=-=-=-=-=-=-=-=-=-=-=-=-=-=-=-=-=-=-=-=-=-=-=-=-=-=-=-=-=-=-=-=-=-=-'||crlf||crlf; -- write the message to the error log file log_file_handle := UTL_FILE.FOPEN (log_file_dir, log_file_name, 'A',maxlinesize); UTL_FILE.PUT_LINE(log_file_handle,msg); UTL_FILE.FCLOSE(log_file_handle); -- send the message by Email mail_conn := UTL_SMTP.open_connection(smtp_relay, mail_port); UTL_SMTP.HELO(mail_conn, smtp_relay); UTL_SMTP.MAIL(mail_conn, sender_address); UTL_SMTP.RCPT(mail_conn, recipient_address); UTL_SMTP.DATA(mail_conn, msg); UTL_SMTP.QUIT(mail_conn); END IF; -- client_program = MyProgram.exe END IF; END; /