Oracle Scheduler Jobs and Database Vault

This post is also available in: Português

As everybody knows, the "Oracle Scheduler" is the official task manager for an Oracle Database. It is a robust and complex tool, allowing the user to create chains, parameterized intervals on several types of metrics, execution windows, etc.

In most cases, when a job is created, modified and executed by its owner, there are not many complications. However, things can get confusing especially when you are working on systems that has the security layer of Oracle Database Vault and if the job was created by an user other than its owner.

In this article, I will show the users that are involved in a Scheduler Job and the role of each.

Well, first, there are basically 3 users participating in an Oracle Scheduler Job:

  • The Job Owner – "OWNER" column of all_scheduler_jobs. view
  • The Job Creator – "JOB_CREATOR" column of all_scheduler_jobs. view
  • The Job latest "Modifier" – This information is not present in all_scheduler_jobs view and must be obtained through queries on dictionary tables.

The attribution of each role is what we will see next.

1 – The Job Owner

The job owner is the schema informed within the JOB_NAME parameter when creating a Job. If omitted, the owner will be the same user who executed the CREATE_JOB procedure. In the next example, the owner is "SCOTT" user.

BEGIN
 DBMS_SCHEDULER.CREATE_JOB(JOB_NAME  => 'SCOTT.JOB1', ..........);
END;
/

The owner will also be the executor. If the task runs a procedure or PL/SQL, this user must therefore be allowed to execute the procedure or privileges on the objects accessed by PL/SQL code. Otherwise, you will receive an error such as "ORA-00942: table or view does not exist".

In case of executing a PL/SQL, the environment variables CURRENT_USER (user whose privileges are currently active) and CURRENT_SCHEMA (active default schema at the time) will obviously be the job owner because, as already mentioned, he is the executor.

However, in case of running a Procedure, the variables CURRENT_USER and CURRENT_SCHEMA show the owner of the Procedure since when it is called, it executes with the privileges of its owner (except if it has "AUTHID CURRENT_USER" and in this case would behave similar to a PL/SQL explained above).

And what happens if we lock the user who owns the job? In this scenario, nothing interferes and the task will continue to run on the scheduled time without any problems. However, if the owner is removed, the scheduled job will also be deleted.

2 – The Job Creator

The job creator is the schema that runs the procedure DBMS_SCHEDULER.CREATE_JOB. If you create a job to another user, you will be defined as the creator of that job.

NOTE: Remember that to create a job in another schema you must have the privilege "CREATE ANY JOB."

The job creator is the user that will connect to the database before running it, despite the executor be the owner. Therefore, the environment variable SESSION_USER always points to the creator. However, those who create do not need any privileges on the objects involved and executed by the job.

During the execution of the scheduled job, if we query the column "USERNAME" from v$session, it returns the job creator user (as he is the one who logged in).

In the latest example, if the SCOTT.JOB1 job was created by INFRAUSR, this would be the output of the v$session while the task was running:

SQL> select username,schemaname,status,program,type,module,action from v$session where module='DBMS_SCHEDULER';
 
USERNAME       SCHEMANAME      STATUS   PROGRAM                      TYPE       MODULE              ACTION
-------------- --------------- -------- ---------------------------- ---------- ------------------- --------
INFRAUSR       SCOTT           ACTIVE   oracle@localhost (J000)      USER       DBMS_SCHEDULER      JOB1
 
SQL>

Despite the user who created be used to log in, if it is locked (or revoked the CREATE SESSION privilege), the job will continue to run normally. This is because the internal behind the sign in for the execution of a job is different. Be aware that, even so, jobs trigger "BEFORE LOGIN" actions.

And what if we delete the user who created the job? In this situation, the job isn't deleted, only disabled. When trying to activate it, the job status in all_scheduler_job_logs will be changed to BROKEN. You will need to recreate it to make it work again.

3 – The Job latest "Modifier"

What a few people know is that Oracle maintains in its records the user who changed a job for the last time. This information is important only if the database has "Database Vault" feature enabled and when the job is also protected by a Realm.

This happens because the last one who changes a particular task is monitored by Oracle Database Vault and only jobs modified by users who have a special privilege on a separated job layer will be authorized to run.

What is the reason for this protection? A user with the "CREATE ANY JOB" privilege could easily compromise the DB or explore a privilege escalation by creating/changing a job from another user who is DBA making that process do whatever he wanted.

Example:

BEGIN
 DBMS_SCHEDULER.CREATE_JOB(
  JOB_NAME => 'SCOTT.JOB_TEMP',
  JOB_TYPE => 'PLSQL_BLOCK',
  JOB_ACTION => q'[BEGIN EXECUTE IMMEDIATE 'GRANT SELECT ON SCOTT.EMP TO MYUSER'; END;]',
  ENABLED => TRUE);
END;
/ 

With Oracle Database Vault feature, this would not be possible.

To get the last user who changed a job, we need to query the "RUN_INVOKER" column on SYS.SCHEDULER$_JOB table:

SQL> col job_creator format a25
SQL> col job_owner format a25
SQL> col job_name format a25
SQL> col perms_check_user format a25
 
SQL> SELECT JU.NAME   "JOB_OWNER",
  2         JO.NAME   "JOB_NAME",
  3         J.CREATOR "JOB_CREATOR",
  4         JR.NAME   "JOB_MODIFIER"
  5  FROM   SYS.SCHEDULER$_JOB J,
  6         SYS.USER$ JU,
  7         SYS.USER$ JR,
  8         SYS.OBJ$ JO
  9  WHERE  J.RUN_INVOKER = JR.USER# (+)
 10  AND    J.OBJ# = JO.OBJ#
 11  AND    JO.OWNER# = JU.USER#
 12  AND    JO.NAME = 'JOB_TEST';
 
JOB_OWNER                 JOB_NAME                  JOB_CREATOR               JOB_MODIFIER
------------------------- ------------------------- ------------------------- -------------------------
SCOTT                     JOB_TEST                  INFRAUSR                  OPERUSR

In the example above, the job was last modified by OPERUSR. This means that if the OPERUSR has no privileges on DB Vault to run it, the job will display the error upon execution:

ORA-12012: error on auto execute of job "SCOTT"."JOB_TEST"
ORA-01031: insufficient privileges
ORA-06512: at line 2

This error has nothing to do with the permissions on the objects involved, because privileges on those objects, as already said, who needs to have is the job owner, which in this case is SCOTT.

So what privilege it is necessary? Only the simple authorization that this job will be allowed to run for the user who last modified it.

In the Database, logged in as a DV Owner account, this authorization may be granted/consulted by running:

SQL> EXEC DVSYS.DBMS_MACADM.AUTHORIZE_SCHEDULER_USER(UNAME => 'OPERUSR', SNAME => 'SCOTT');
 
PL/SQL procedure successfully completed.
 
SQL> col grantee format a30
SQL> col schema format a30
SQL> select * from dvsys.dba_dv_job_auth;
 
GRANTEE                        SCHEMA
------------------------------ ------------------------------
OPERUSR                        SCOTT

Lastly, as we saw in this article, a job may be more complex than it seems. If you are having problems privilege in any of your scheduled tasks, be sure to check what is the role of each user who is participating and that all have the appropriate privileges.

 

Have you enjoyed? Please leave a comment or give a 👍!

4 comments

Skip to comment form

  1. Great explanation!
    Thank you for your contributions to the community.

  2. This is helpful to understand the DBA details more Thanx

    • Youssef on January 15, 2018 at 03:59
    • Reply

    wonderful, it helped me man , thanks alot

    • Mpho on April 24, 2018 at 11:08
    • Reply

    You saved me a lot of time. Thank you very much.

Leave a Reply

Your email address will not be published.