While sending mail using utl_mail or utl_stmp in oracle 11g, you may get access denied error:

begin
utl_mail.send(sender => ‘admin@dbaclass.com’,
recipients => ‘admin@dbaclass.com’,
subject => ‘MAIL from ADMIn of dbaclass’,
message => ‘Do visit dbaclass’);
end;
/

*
ERROR at line 1:
ORA-24247: network access denied by access control list (ACL)
ORA-06512: at “SYS.UTL_MAIL”, line 662
ORA-06512: at “SYS.UTL_MAIL”, line 679
ORA-06512: at line 2

 

Solution:

From 11g onward, to send mail using UTL_MAIL or UTL_SMTP , ACL need to be created in the database.

Set the SMTP_OUT_SERVER parameter

SQL> alter system set smtp_out_server='mailhost.dbaclass.com' scope=both;

System altered.

Now create ACLS
Suppose the user APPUSER want to send mail from procedure.

--- creating ACL as below 
exec DBMS_NETWORK_ACL_ADMIN.CREATE_ACL('send_mail.xml','Allow mail to be send', 'APPUSER', TRUE, 'connect');
commit;
----Grant the connect and resource privilege as below
exec DBMS_NETWORK_ACL_ADMIN.ADD_PRIVILEGE('send_mail.xml','APPUSER',TRUE, 'connect');
exec DBMS_NETWORK_ACL_ADMIN.ADD_PRIVILEGE('send_mail.xml','APPUSER',TRUE, 'resolve');
exec DBMS_NETWORK_ACL_ADMIN.ASSIGN_ACL('send_mail.xml','*',25);
commit;

 

Now try to send mail:

SQL> conn appuser
Enter password:
Connected.
SQL> begin
  utl_mail.send(sender     => 'admin@dbaclass.com',
                recipients => 'admin@dbaclass.com',
                subject    => 'MAIL from ADMIn of dbaclass',
                message    => 'Do visit dbaclass');
end;
/  2    3    4    5    6    7

PL/SQL procedure successfully completed.