ORA-24247: network access denied by access control list (ACL)
Yesterday I was trying to send mail from my Oracle Database and I got below mentioned error :-
ERROR at line 1:
ORA-24247: network access denied by access control list (ACL)
ORA-06512: at "CINP01314", line 255
ORA-06512: at line 21
In 11g Database , we need to create and configure ACL(access control list). In order to use PL/SQL network utility pakages like UTL_SMTP, UTL_MAIL, we have to configure an ACL file that provides fine grained access to external network services.
Steps to configure :-
1. Find out your SMTP outgoing mail server and configure the database parameter smtp_out_server.
SQL> alter system set smtp_out_server= '10.10.10.10' ;
############### only for UTL_MAIL package this parameter needs to be set#################
system altered
2. Create an access control list file :-
begin
DBMS_NETWORK_ACL_ADMIN
.create_acl (
acl => 'ACL_PERMISSION.xml',
description => 'Enables mail to be sent',
principal => 'ARVIND', -- USERNAME to which access has to be granted
is_grant => true,
privilege => 'connect');
commit;
end;
/
PL/SQL procedure successfully completed.
-- Drop an access control list :-
BEGIN
DBMS_NETWORK_ACL_ADMIN.drop_acl (
acl => '/sys/acls/ACL_PERMISSION.xml');
COMMIT;
END;
/
PL/SQL procedure successfully completed.
3. Assign this ACL to your SMTP network host for your email server :-
begin
dbms_network_acl_admin.assign_acl (
acl => 'ACL_PERMISSION.xml',
host => '100.02.03.04', -- SMTP network host
lower_port => 25);
commit;
end;
/
PL/SQL procedure successfully completed.
-- TO drop ACL assignments :-
begin
dbms_network_acl_admin.unassign_acl (
acl => 'ACL_PERMISSION.xml',
host => '100.02.03.04', -- SMTP network host
lower_port => 25);
COMMIT;
end;
/
PL/SQL procedure successfully completed.
4. Grant permission to use ACL file :-
begin
DBMS_NETWORK_ACL_ADMIN.add_privilege (
acl => 'ACL_PERMISSION.xml',
principal => 'ARVIND',
is_grant => TRUE,
privilege => 'connect');
COMMIT;
end;
/
PL/SQL procedure successfully completed.
-- If we want to delete or revoke this permission :-
BEGIN
DBMS_NETWORK_ACL_ADMIN.delete_privilege (
acl => '/sys/acls/ACL_PERMISSION.xml',
principal => 'ARVIND',
is_grant => TRUE,
privilege => 'connect');
COMMIT;
END;
/
PL/SQL procedure successfully completed.
5. Check that for ARVIND user permission has been set properly :-
SQL> col HOST for a45
SQL> SELECT host, lower_port, upper_port, privilege, status FROM user_network_acl_privileges;
HOST LOWER_PORT UPPER_PORT PRIVILEGE STATUS
--------------------------------------------- ----------------- ---------------- --------------------- ---------------------
100.02.03.04 25 25 connect GRANTED
<your smtp server host name or address> connect GRANTED
black connect GRANTED
--Status column must have value granted.
SQL> SELECT DECODE(
DBMS_NETWORK_ACL_ADMIN.check_privilege('ACL_PERMISSION.xml', 'ARVIND', 'connect'),
1, 'GRANTED', 0, 'DENIED', NULL) privilege
FROM dual;
PRIVILEGE
---------------------
GRANTED
SQL> COLUMN acl FORMAT A30
SQL> COLUMN principal FORMAT A30
SQL> SELECT acl,
principal,
privilege,
is_grant,
TO_CHAR(start_date, 'DD-MON-YYYY') AS start_date,
TO_CHAR(end_date, 'DD-MON-YYYY') AS end_date
FROM dba_network_acl_privileges;.
ACL PRINCIPAL PRIVILEGE IS_GRANT START_DATE END_DATE
------------------------------ ------------------------------ --------------------- --------------- --------------------------------- ---------------------------------
/sys/acls/ACL_PERMISSION.xml ARVIND connect true
Once you got output like above queries. You can test you procedure to send mail, it will work.
As we have create ACL for ACL_PERMISSION.xml we can create for utl_mail.xml and utl_tcp.xml after creation of both these ACL's output of above query will be like below :-
ACL PRINCIPAL PRIVILEGE IS_GRANT START_DATE END_DATE
------------------------------ ------------------------------ --------------------- --------------- --------------------------------- ---------------------------------
/sys/acls/utl_mail.xml ARVIND connect true
/sys/acls/ACL_PERMISSION.xml ARVIND connect true
/sys/acls/utl_tcp.xml ARVIND connect true
TO enable this ACL permission for a different USER other than above user(ARVIND) :-
Connect with TEST user and run below mentioned :-
begin
DBMS_NETWORK_ACL_ADMIN.add_privilege (
acl => 'ACL_PERMISSION.xml',
principal => 'TEST',
is_grant => FALSE,
privilege => 'connect');
commit;
end;
/
PL/SQL procedure successfully completed.
begin
dbms_network_acl_admin.assign_acl (
acl => 'ACL_PERMISSION.xml',
host => '100.02.03.04',
lower_port => 25);
end;
/
PL/SQL procedure successfully completed.
SQL> COLUMN acl FORMAT A30
SQL> COLUMN principal FORMAT A30
SQL> SELECT acl,
principal,
privilege,
is_grant,
TO_CHAR(start_date, 'DD-MON-YYYY') AS start_date,
TO_CHAR(end_date, 'DD-MON-YYYY') AS end_date
FROM dba_network_acl_privileges;.
ACL PRINCIPAL PRIVILEGE IS_GRANT START_DATE END_DATE
------------------------------ ------------------------------ --------------------- --------------- --------------------------------- ---------------------------------
/sys/acls/ACL_PERMISSION.xml ARVIND connect true
/sys/acls/ACL_PERMISSION.xml TEST connect false
-- This query has to be run with TEST user and Status column should have value "GRANTED"
SQL> SELECT host, lower_port, upper_port, privilege, status FROM user_network_acl_privileges;
HOST LOWER_PORT UPPER_PORT PRIVILEGE STATUS
--------------------------------------------- ----------------- ---------------- --------------------- ---------------------
100.02.03.04 25 25 connect GRANTED
<your smtp server host name or address> connect GRANTED
black connect GRANTED
No comments:
Post a Comment