Scheduler Does Not Support Object Privileges Granted Through Roles (Doc ID 1102124.1)

Last updated on NOVEMBER 04, 2015

Applies to:

Oracle Server - Enterprise Edition - Version: 10.1.0.2 to 11.2.0.2.0 - Release: 10.1 to 11.2
Information in this document applies to any platform.

Symptoms

The Scheduler does not support the object privileges granted via roles.
When running the scheduler procedures, any object privilege required by the scheduler, if granted via a role, is not recognized and the procedure fails with insufficient privileges (ORA-27486, ORA-27373).


conn / as sysdba
drop user com cascade;
drop user test cascade;

create user com identified by com;
grant dba to com;

connect com/com

create table COM_LOG
(
TEXTE VARCHAR2(1000) not null
)
tablespace USERS;

create or replace procedure TEST_PROC authid current_user is
pragma autonomous_transaction;
begin
insert into COM_LOG(texte)
values('test');
commit;
end TEST_PROC;
/

begin
dbms_scheduler.create_program (
program_name => 'TEST_PROGRAM',
program_action=> 'TEST_PROC',
program_type => 'STORED_PROCEDURE',
number_of_arguments => 0,
enabled => TRUE) ;
dbms_schedulerenable('TEST_PROGRAM');
end;
/

create role COM_UTIL;

grant select, insert on COM_LOG to COM_UTIL;
grant execute on TEST_PROC to COM_UTIL;
grant execute on COMTEST_PROGRAM to COM_UTIL;
grant create job to COM_UTIL;

conn / as sysdba
create user test identified by test;
grant connect, resource to test;
grant COM_UTIL to test;

--Fails
conn test/test
begin
dbms_scheduler.create_job (
job_name => 'TEST_PROGRAM',
program_name => 'COMTEST_PROGRAM',
start_date => SYSTIMESTAMP,
enabled => TRUE);
end;
/

ERROR at line 1:
ORA-27486: insufficient privileges
ORA-06512: at "SYSDBMS_ISCHED", line 99
ORA-06512: at "SYSDBMS_SCHEDULER", line 386
ORA-06512: at line 2


--Granting the object privilege directly solves the problem:
conn com/com
grant execute on COMTEST_PROGRAM to test;

conn test/test
begin
dbms_scheduler.create_job (
job_name => 'TEST_PROGRAM',
program_name => 'COMTEST_PROGRAM',
start_date => SYSTIMESTAMP,
enabled => TRUE);
end;
/

--Also this works (granting the corresponding system privilege)
revoke execute on COMTEST_PROGRAM from test;
grant execute any program to com_util;
begin
dbms_scheduler.create_job (
job_name => 'TEST_PROGRAM',
program_name => 'COMTEST_PROGRAM',
start_date => SYSTIMESTAMP,
enabled => TRUE);
end;
/


Cause

Sign In with your My Oracle Support account

Don't have a My Oracle Support account? Click to get started

My Oracle Support provides customers with access to over a
Million Knowledge Articles and hundreds of Community platforms