SMTP Exceptions in PPAS9.0
Till PPAS 9.0, UTL_SMTP package has no specific named Exceptions for Transient_error, Invalid_operation and Permanent Error. However, Oracle provide following types of named exceptions for SMTP:
1. INVALID_OPERATION:
Raised when an invalid operation is made. In other words, calling API other than write_data(), write_raw_data() or close_data() after open_data() is called, or calling write_data(), write_raw_data() or close_data() without first calling open_data().
2. TRANSIENT_ERROR:
Raised when receiving a reply code in 400 range.
3. PERMANENT_ERROR:
Raised when receiving a reply code in 500 range.
Oracle users who use SMTP packages, they also use above exceptions extensively to track the SMTP Error/Message and perform some handling on basis of exception.
Since, till now PPAS doesn't have these exceptions, therefore people stuck on finding workaround for such exception.
To make this easy, I did some research and made following workaround, which user can use in PPAS for SMTP Exceptions as they do in Oracle.
Following are workarounds for SMTP named Exceptions:
There is no direct way to trap SMTP reply code, However PPAS SQLERRM does have description of SMTP Reply code. So using SQLERRM, user can implement or defined named Exceptions, which is pretty simple and straight.
Easiest way of doing is to create functions, which can decide if exception error is TRANSIENT, PERMANENT or INVALID_OPERATION. So, user can create following functions in PPAS:
1. Function For transient Error Message:
2. Function for Permanent Error Message:
Below are some working examples:
In Oracle (INVALID_OPERATION) :
Example 2: In Oracle (UTL_SMTP.TRANSIENT_ERROR ):
1. INVALID_OPERATION:
Raised when an invalid operation is made. In other words, calling API other than write_data(), write_raw_data() or close_data() after open_data() is called, or calling write_data(), write_raw_data() or close_data() without first calling open_data().
2. TRANSIENT_ERROR:
Raised when receiving a reply code in 400 range.
3. PERMANENT_ERROR:
Raised when receiving a reply code in 500 range.
Oracle users who use SMTP packages, they also use above exceptions extensively to track the SMTP Error/Message and perform some handling on basis of exception.
Since, till now PPAS doesn't have these exceptions, therefore people stuck on finding workaround for such exception.
To make this easy, I did some research and made following workaround, which user can use in PPAS for SMTP Exceptions as they do in Oracle.
Following are workarounds for SMTP named Exceptions:
There is no direct way to trap SMTP reply code, However PPAS SQLERRM does have description of SMTP Reply code. So using SQLERRM, user can implement or defined named Exceptions, which is pretty simple and straight.
Easiest way of doing is to create functions, which can decide if exception error is TRANSIENT, PERMANENT or INVALID_OPERATION. So, user can create following functions in PPAS:
1. Function For transient Error Message:
CREATE OR REPLACE FUNCTION SMTP_TRANSIENT_ERROR(text) RETURNS boolean As $$ SELECT CASE WHEN $1 ILIKE '%Service not available%' OR $1 ILIKE '%Requested mail action not taken%' OR $1 ILIKE '%Requested action terminated%' OR $1 ILIKE '%Requested action not taken%' OR $1 ILIKE '%You have no mail%' OR $1 ILIKE '%TLS not available due to temporary reason%. Encryption required for requested authentication mechanism%' OR $1 ILIKE '%Unable to queue messages for %' OR $1 ILIKE '%Node%not allowed%' THEN true ELSE false END from dual; $$ language sql;
2. Function for Permanent Error Message:
CREATE OR REPLACE FUNCTION SMTP_PERMANENT_ERROR(text) RETURNS Boolean AS $$ SELECT CASE WHEN $1 ILIKE '%Syntax error%command unrecognized%' OR $1 ILIKE '%Syntax error in parameters or arguments%' OR $1 ILIKE '%Command not implemented%' OR $1 ILIKE '%Bad sequence of commands%' OR $1 ILIKE '%Command parameter not implemented%' OR $1 ILIKE '%does not accept mail%' OR $1 ILIKE '%Must issue a STARTTLS command first. Encryption required for requested authentication mechanism%' OR $1 ILIKE '%Authentication mechanism is too weak%' OR $1 ILIKE '%Encryption required for requested authentication mechanism%' OR $1 ILIKE '%Requested action not taken%' OR $1 ILIKE '%User not local; please try%' OR $1 ILIKE '%Requested mail action terminated: exceeded storage allocation%' OR $1 ILIKE '%Requested action not taken:%' OR $1 ILIKE '%Transaction failed%' THEN true ELSE false END FROM DUAL; $$ language sql3. Function for INVALID_OPERATION
CREATE OR REPLACE FUNCTION SMTP_INVALID_OPERATION(TEXT) RETURNS BOOL AS $$ SELECT CASE WHEN $ ILIKE '%INVALID%OPERATION%STATE%' THEN TRUE ELSE FALSE END FROM DUAL; $$ Language sql;
Below are some working examples:
In Oracle (INVALID_OPERATION) :
CREATE OR REPLACE PROCEDURE SEND_MAIL ( msg_to varchar2, msg_subject varchar2, msg_text varchar2 ) IS c utl_smtp.connection; rc integer; msg_from varchar2(50) := 'Oracle9.2'; mailhost VARCHAR2(30) := '127.0.0.1'; -- local database host BEGIN c := utl_smtp.open_connection(mailhost, 25); -- SMTP on port 25 utl_smtp.helo(c, mailhost); utl_smtp.mail(c, msg_from); utl_smtp.rcpt(c, msg_to); utl_smtp.write_data(c, 'MESSG'||UTL_TCP.CRLF); --Added By me utl_smtp.data(c,'From: Oracle Database' || utl_tcp.crlf || 'To: ' || msg_to || utl_tcp.crlf || 'Subject: ' || msg_subject || utl_tcp.crlf || msg_text); utl_smtp.quit(c); EXCEPTION WHEN UTL_SMTP.INVALID_OPERATION THEN dbms_output.put_line(' Invalid Operation in Mail attempt using UTL_SMTP.'); WHEN UTL_SMTP.TRANSIENT_ERROR THEN dbms_output.put_line(' Temporary e-mail issue - try again'); WHEN UTL_SMTP.PERMANENT_ERROR THEN dbms_output.put_line(' Permanent Error Encountered.'); END; SQL> exec send_mail(msg_to=>'vibhor.aim@gmail.com', - msg_subject => 'Hello from Oracle', - msg_text => 'This is the body of the message'- ); Invalid Operation in Mail attempt using UTL_SMTP. PL/SQL procedure successfully completed.In PPAS:
CREATE OR REPLACE PROCEDURE SEND_MAIL ( msg_to varchar2, msg_subject varchar2, msg_text varchar2 ) IS c utl_smtp.connection; rc integer; msg_from varchar2(50) := 'PPAS 9.0'; mailhost VARCHAR2(30) := '127.0.0.1'; -- local database host BEGIN c := utl_smtp.open_connection(mailhost, 25); -- SMTP on port 25 utl_smtp.helo(c, mailhost); utl_smtp.mail(c, msg_from); utl_smtp.rcpt(c, msg_to); utl_smtp.write_data(c, 'MESSG'||UTL_TCP.CRLF); --Added By me utl_smtp.data(c,'From: Oracle Database' || utl_tcp.crlf || 'To: ' || msg_to || utl_tcp.crlf || 'Subject: ' || msg_subject || utl_tcp.crlf || msg_text); utl_smtp.quit(c); EXCEPTION WHEN OTHERS THEN IF SMTP_INVALID_OPERATION(SQLERRM) THEN DBMS_OUTPUT.PUT_LINE('Invalid Operation in Mail attempt using UTL_SMTP.'); ELSIF SMTP_TRANSIENT_ERROR(SQLERRM) THEN DBMS_OUTPUT.PUT_LINE(' Temporary e-mail issue - try again'); ELSIF SMTP_PERMANENT_ERROR(SQLERRM) THEN DBMS_OUTPUT.PUT_LINE(' Permanent Error Encountered.'); ELSE DBMS_OUTPUT.PUT_LINE('SQLCODE: '||SQLCODE||' Error Message: '||SQLERRM); END IF; END; EDB-SPL Procedure successfully completed edb=# exec send_mail(msg_to=>'vibhor.aim@gmail.com', edb(# msg_subject => 'Hello from PPAS', edb(# msg_text => 'This is the body of the message'); Invalid Operation in Mail attempt using UTL_SMTP. EDB-SPL Procedure successfully completed
Example 2: In Oracle (UTL_SMTP.TRANSIENT_ERROR ):
CREATE OR REPLACE PROCEDURE SEND_MAIL ( msg_to varchar2, msg_subject varchar2, msg_text varchar2 ) IS c utl_smtp.connection; rc integer; msg_from varchar2(50) := 'Oracle9.2'; mailhost VARCHAR2(30) := '192.168.23.25'; -- local database host BEGIN c := utl_smtp.open_connection(mailhost, 25); -- SMTP on port 25 utl_smtp.helo(c, mailhost); utl_smtp.mail(c, msg_from); utl_smtp.rcpt(c, msg_to); utl_smtp.write_data(c, 'MESSG'||UTL_TCP.CRLF); --Added By me utl_smtp.data(c,'From: Oracle Database' || utl_tcp.crlf || 'To: ' || msg_to || utl_tcp.crlf || 'Subject: ' || msg_subject || utl_tcp.crlf || msg_text); utl_smtp.quit(c); EXCEPTION WHEN UTL_SMTP.INVALID_OPERATION THEN dbms_output.put_line(' Invalid Operation in Mail attempt using UTL_SMTP.'); WHEN UTL_SMTP.TRANSIENT_ERROR THEN dbms_output.put_line(' Temporary e-mail issue - try again'); WHEN UTL_SMTP.PERMANENT_ERROR THEN dbms_output.put_line(' Permanent Error Encountered.'); END; SQL> exec send_mail(msg_to=>'vibhor.aim@gmail.com', - msg_subject => 'Hello from Oracle', - msg_text => 'This is the body of the message'- );> > > Temporary e-mail issue - try again PL/SQL procedure successfully completed.In PPAS:
CREATE OR REPLACE PROCEDURE SEND_MAIL ( msg_to varchar2, msg_subject varchar2, msg_text varchar2 ) IS c utl_smtp.connection; rc integer; msg_from varchar2(50) := 'PPAS 9.0'; mailhost VARCHAR2(30) := '192.168.23.25'; -- local database host BEGIN c := utl_smtp.open_connection(mailhost, 25); -- SMTP on port 25 utl_smtp.helo(c, mailhost); utl_smtp.mail(c, msg_from); utl_smtp.rcpt(c, msg_to); utl_smtp.write_data(c, 'MESSG'||UTL_TCP.CRLF); --Added By me utl_smtp.data(c,'From: Oracle Database' || utl_tcp.crlf || 'To: ' || msg_to || utl_tcp.crlf || 'Subject: ' || msg_subject || utl_tcp.crlf || msg_text); utl_smtp.quit(c); EXCEPTION WHEN OTHERS THEN IF SMTP_INVALID_OPERATION(SQLERRM) THEN DBMS_OUTPUT.PUT_LINE('Invalid Operation in Mail attempt using UTL_SMTP.'); ELSIF SMTP_TRANSIENT_ERROR(SQLERRM) THEN DBMS_OUTPUT.PUT_LINE(' Temporary e-mail issue - try again'); ELSIF SMTP_PERMANENT_ERROR(SQLERRM) THEN DBMS_OUTPUT.PUT_LINE(' Permanent Error Encountered.'); ELSE DBMS_OUTPUT.PUT_LINE('SQLCODE: '||SQLCODE||' Error Message: '||SQLERRM); END IF; END; edb=# exec send_mail(msg_to=>'vibhor.aim@gmail.com', edb(# msg_subject => 'Hello from PPAS', edb(# msg_text => 'This is the body of the message'); Temporary e-mail issue - try again EDB-SPL Procedure successfully completed edb=#Have fun!
Comments
Post a Comment