Showing posts with label Scheduler. Show all posts
Showing posts with label Scheduler. Show all posts

Tuesday, May 18, 2021

How to find the opening and closing time for the maintenance windows in an Oracle database

To see the last 7 days of opening/closing time for the maintenance windows, use this query:
SELECT window_name,to_char(start_time,'dd.mm.yyyy hh24:mi:ss') "start time", duration 
FROM dba_autotask_schedule 
ORDER BY start_time desc fetch first 7 rows only;
Example output:
WINDOW_NAME start time DURATION
SATURDAY_WINDOW 19.06.2021 06:00:00 +00 20:00:00.000000
FRIDAY_WINDOW 18.06.2021 22:00:00 +00 04:00:00.000000
THURSDAY_WINDOW 17.06.2021 22:00:00 +00 04:00:00.000000
WEDNESDAY_WINDOW 16.06.2021 22:00:00 +00 04:00:00.000000
TUESDAY_WINDOW 15.06.2021 22:00:00 +00 04:00:00.000000
MONDAY_WINDOW 14.06.2021 22:00:00 +00 04:00:00.000000
SUNDAY_WINDOW 13.06.2021 06:00:00 +00 20:00:00.000000

Friday, January 8, 2021

How to disable a scheduler job in a another schema

Use the syntax
connect system
set serveroutput on
EXECUTE DBMS_SCHEDULER.DISABLE(name=>'SCOTT.UPDATE_COMMISIONS');
You cannot login as SYS to perform this operation, you need to be logged in as another user with the required preivileges (such as SYSTEM, in this case). Documented here

Tuesday, February 12, 2019

How to remove a job from the job queue


Today I saw the following error message in the alert log of my database:
2019-02-12T13:27:30.506714+01:00
Errors in file /u01/oracle/diag/rdbms/proddb01/proddb01/trace/proddb01_j000_20661.trc:
ORA-12012: error on auto execute of job 98
ORA-30967: operation directly on the Path Table is disallowed
This error was connected to a procedure I had made earlier, in this post.

In short, the procedure creates a job using dbms_jobs, and executes it thereafter. Because an error occured during job execution, the job appeared to be jamming connections to the database. The job needed to be dropped immediately.

To remove the job, use either the dbms_job.remove procedure, like this:
sqlplus username/password

begin
  sys.dbms_job(98);
  commit;
end;
/

If you do not have the password for schema owning the job, Use the undocumented procedure sys.dbms_ijob, like this:
sqlplus / as sysdba
begin
  sys.dbms_ijob(98);
  commit;
end;
/

Tuesday, April 10, 2018

How to change the start time for a maintenance window

For example, if you want to change the start time for the MONDAY_WINDOW from the default 22:00 to 23:59, use the following syntax:

BEGIN
DBMS_SCHEDULER.DISABLE(name=>'"SYS"."MONDAY_WINDOW"',force=>TRUE);
END;
/

BEGIN
DBMS_SCHEDULER.SET_ATTRIBUTE(name=>'"SYS"."MONDAY_WINDOW"',attribute=>'REPEAT_INTERVAL',value=>'FREQ=WEEKLY;BYDAY=MON;BYHOUR=23;BYMINUTE=59;BYSECOND=0');
END;
/

BEGIN
DBMS_SCHEDULER.ENABLE(name=>'"SYS"."MONDAY_WINDOW"');
END;
/

Tuesday, February 16, 2016

How to remove dbms_scheduler jobs

To delete an obsolete scheduler job, use the procedure dbms_scheduler.drop_job procedure.
In a recent case, a large number of obsolete dbms_Scheduler jobs were laying around in the database, and needed a cleanup.
Most of them were not enabled, and all stakeholders deemed it safe to remove the jobs.

To loop through the jobs owned by the schema, I used the following simple script:
connect scott/tiger
set serveroutput on
set trimspool on
spool /tmp/drop_mva_scheduler_jobs.log
DECLARE

  CURSOR C1 IS
  SELECT JOB_NAME
  FROM USER_SCHEDULER_JOBS
  WHERE ENABLED='FALSE';

BEGIN
 FOR l_rec IN C1 LOOP
   dbms_output.put_line('Now dropping job: ' || l_rec.job_name);
   dbms_scheduler.drop_job(job_name=>'' || l_rec.job_name || '' );
 END LOOP;
END;
/
exit


Sources: Oracle Documentation

Wednesday, May 27, 2015

How to create a stored procedure for partition maintenance, executed by the Oracle Scheduler.

I needed to setup a small job that would remove partitions from a table with records older than 35 days.
The procedure should be flexible enough to accept different tables in different schemas, and there should be some basic logging, too.

Below is how I solved it.


First, grant permission, setup the logging table and add a sequence:

connect / as sysdba
grant select on dba_tab_partitions to scott;

connect scott/tiger

whenever sqlerror continue
drop sequence part_maint_seq;

create sequence part_maint_seq
increment by 1
start with 1
nomaxvalue
nominvalue
nocycle;

drop table partition_maintenance;

create table partition_maintenance(
    opid           number not null,
    table_owner    varchar2(8),
    table_name     varchar2(30),
    partition_name varchar2(30),
    operation      varchar2(10),
    success        char(1),
    exe_date       date,
    exec_by        varchar2(30) default 'automatic',
    errormsg       varchar2(512)
);

alter table partition_maintenance
add constraint part_maint_pk primary key (opid);

Then, create the stored procedure that will do the job. It requires two parameters to be passed to it: table owner and table name. Note that the procedure will need to be called with invoker's right, since it is accessing DBA_TAB_PARTITION:
connect scott/tiger

set serveroutput on

CREATE OR REPLACE PROCEDURE DROP_PARTITIONS ( towner IN VARCHAR2, tname IN VARCHAR2) AUTHID CURRENT_USER AS

  PNAME DBA_TAB_PARTITIONS.PARTITION_NAME%TYPE;
  L_DATA LONG;
  V_HVD DATE;
  V_PURGE_DATE DATE;
  SQLTORUN VARCHAR2(200);

  CURSOR PART_NAME
  IS
  SELECT PARTITION_NAME
    FROM DBA_TAB_PARTITIONS
    WHERE TABLE_NAME =  UPPER(tname)
    AND   TABLE_OWNER = UPPER(towner)
    AND   INTERVAL='YES'
    ORDER BY partition_position;

BEGIN

    OPEN PART_NAME;
    FETCH PART_NAME INTO PNAME;
    IF PART_NAME%ROWCOUNT = 0 THEN
        dbms_output.put_line('no such table as ' || UPPER(towner) ||'.'||UPPER(tname) );
            INSERT INTO PARTITION_MAINTENANCE (OPID, TABLE_OWNER,TABLE_NAME,PARTITION_NAME, OPERATION, SUCCESS, EXE_DATE, ERRORMSG)
                VALUES (PART_MAINT_SEQ.NEXTVAL,UPPER(towner),UPPER(tname),PNAME ,'DROP','N', SYSDATE, 'No table such as '|| towner || '.' || tname );
                COMMIT;
    END IF;
    WHILE PART_NAME%FOUND
        LOOP
            --DBMS_OUTPUT.PUT_LINE( pname );
            SELECT HIGH_VALUE
            INTO L_DATA
            FROM DBA_TAB_PARTITIONS
            WHERE TABLE_OWNER= UPPER(towner)
            AND   TABLE_NAME = UPPER(tname)
            AND PARTITION_NAME = PNAME;

            --dbms_output.put_line('partition name: ' || pname || ' ' ||  trim (substr ( l_data, 12, 10 )  ) );
             V_HVD := TO_DATE(TRIM (SUBSTR ( L_DATA, 12, 10 ))  ,'YYYY-MM-DD');
            -- dbms_output.put_line('high value date: ' || v_hvd);
           V_PURGE_DATE := TRUNC(SYSDATE)-35;
            --dbms_output.put_line('purge date: ' || v_purge_date);
            IF V_HVD < V_PURGE_DATE THEN
               DBMS_OUTPUT.PUT_LINE('partition ' || PNAME ||' too old, high value date for partition is: ' || V_HVD);
               -- drop statement goes here
               SQLTORUN := 'alter table ' || towner || '.' || tname || ' drop partition ' || PNAME || ' UPDATE INDEXES';
               DBMS_OUTPUT.PUT_LINE(SQLTORUN);
               EXECUTE IMMEDIATE SQLTORUN;
               -- logging to a separate table goes here
               INSERT INTO PARTITION_MAINTENANCE (OPID, TABLE_OWNER,TABLE_NAME,PARTITION_NAME, OPERATION, SUCCESS, EXE_DATE, ERRORMSG)
               VALUES (PART_MAINT_SEQ.NEXTVAL,UPPER(towner),UPPER(tname),PNAME ,'DROP','Y', SYSDATE, 'Partition ' || pname || ' of table ' || towner || '.' || tname || ' was dropped.');
               COMMIT;
            END IF;
            FETCH PART_NAME INTO PNAME;
        END LOOP;

    CLOSE PART_NAME;

END;
/
Finally, create a program of type "STORED_PROCEDURE", define its arguments, and create a job that executes the program on a regular basis:
whenever sqlerror continue
set serveroutput on

BEGIN
DBMS_SCHEDULER.DROP_JOB(
    job_name        => 'DROP_PARTITION_5WEEK'
  );
  DBMS_SCHEDULER.DROP_PROGRAM(
     program_name       => 'DROP_PARTITION_PROG'
  );
  DBMS_SCHEDULER.create_program (
    program_name        => 'DROP_PARTITION_PROG',
    program_type        => 'STORED_PROCEDURE',
    program_action      => 'DROP_PARTITIONS',
    number_of_arguments => 2,
    enabled             => FALSE,
    comments            => 'Program to drop partitions with contents older than 35 days..');

  DBMS_SCHEDULER.define_program_argument (
    program_name      => 'DROP_PARTITION_PROG',
    argument_name     => 'towner',
    argument_position => 1,
    argument_type     => 'VARCHAR2',
    default_value     => 'SCOTT');

  DBMS_SCHEDULER.define_program_argument (
    program_name      => 'DROP_PARTITION_PROG',
    argument_name     => 'tname',
    argument_position => 2,
    argument_type     => 'VARCHAR2',
    default_value     => 'SALES');

  DBMS_SCHEDULER.enable( name => 'DROP_PARTITION_PROG');

  DBMS_SCHEDULER.CREATE_JOB
    (
    job_name        => 'DROP_PARTITION_5WEEK',
    program_name    => 'DROP_PARTITION_PROG',
    start_date      => TO_TIMESTAMP_TZ('2015/05/26 21:45:00.000000 +02:00','yyyy/mm/dd hh24:mi:ss.ff tzh:tzm'),
    repeat_interval => 'FREQ=WEEKLY;',
    end_date        => NULL,
    enabled         => TRUE,
    comments        => 'Job will execute the program drop_partitions.');
END;
/

Wednesday, April 29, 2015

Thursday, July 10, 2014

How to drop stuck purge job created through DBMS_AUDIT_MGMT


In the process of implementing automatic purging of the audit trail, I came across a problem that I was really puzzled by: In the debugging process I had to drop and recreate the purge job that I had previously created through the dbms_audit_mgmt package.

I was completely unable to drop a particular scheduler job. All attempts threw different errors:

Trying to drop the job through the dbms_audit_mgmt.drop_purge_job procedure:
dbms_audit_mgmt.drop_purge_job(audit_trail_purge_name=>'PURGE_ALL_AUDIT_TRAILS');

Then trying to drop it directly through the dbms_scheduler.drop_job procedure:
dbms_scheduler.drop_job(job_name=>'PURGE_ALL_AUDIT_TRAILS',force=>TRUE);

Both attempts returned the error:
ERROR at line 1:
ORA-27475: "SYS.PURGE_ALL_AUDIT_TRAILS" must be a job
ORA-06512: at "SYS.DBMS_ISCHED", line 224
ORA-06512: at "SYS.DBMS_SCHEDULER", line 657
ORA-06512: at line 2

Trying to enable the job explicitly, in case the scheduled job was in an unknown state to the database:
exec dbms_scheduler.enable(name=>'PURGE_ALL_AUDIT_TRAILS');

which resulted in
ERROR at line 1:
ORA-27476: SYS.PURGE_ALL_AUDIT_TRAILS does not exist
ORA-06512: at "SYS.DBMS_ISCHED", line 4440
ORA-06512: at "SYS.DBMS_SCHEDULER", line 2803
ORA-06512: at line 1

Trying to recreate the job:
BEGIN
    DBMS_AUDIT_MGMT.create_purge_job(
      audit_trail_type           => DBMS_AUDIT_MGMT.AUDIT_TRAIL_ALL,
      audit_trail_purge_interval => 24 /* hours */,
      audit_trail_purge_name     => 'PURGE_ALL_AUDIT_TRAILS',
      use_last_arch_timestamp    => TRUE);
  EXCEPTION
    WHEN OTHERS THEN
     DBMS_OUTPUT.PUT_LINE(sqlerrm(sqlcode));
  END;
  /

Result:
ORA-46254: 'PURGE_ALL_AUDIT_TRAILS' already exists

Particuarly the last two error messages were discouraging. You cannot enable the job, because it doesn't exist, neither can you recreate the job, since it already DOES exist.

Solution:
From Oracle Support 1252235.1 "Unable to Create or Drop Purge Job Using DBMS_AUDIT_MGMT".

In short, log on as user sys and execute the following SQL statements:
SELECT JOB_NAME,STATE
FROM DBA_SCHEDULER_JOBS
WHERE JOB_NAME = 'PURGE_ALL_AUDIT_TRAILS'; <-- No rows should be returned

SELECT JOB_NAME,JOB_STATUS,AUDIT_TRAIL
FROM DBA_AUDIT_MGMT_CLEANUP_JOBS
WHERE JOB_NAME = 'PURGE_ALL_AUDIT_TRAILS'; <-- 1 row should be returned, the job that's "stuck"

DELETE FROM SYS.DAM_CLEANUP_JOBS$
WHERE JOB_NAME = 'PURGE_ALL_AUDIT_TRAILS'; <-- Delete the row from one of Oracle's internal tables,

COMMIT; <-- commit the change
And you're done, your job can be recreated, after which it will turn up as usual when you query the DBA_SCHEDULER_JOBS view:
SELECT STATE,ENABLED
FROM DBA_SCHEDULER_JOBS
WHERE  JOB_NAME = 'PURGE_ALL_AUDIT_TRAILS';
STATE ENABLED
SCHEDULED TRUE

Tuesday, July 8, 2014

How to purge the log entries for a specific dbms_scheduler job

exec dbms_scheduler.purge_log(log_history=>0, job_name=>'YOUR_JOB_NAME');

Zero is actually default for log_history, it doesn't have to be specified.

If you want to save some of the logs, you can specify for example that Oracle should only purge logs older than, say, two days:

exec dbms_scheduler.purge_log(log_history=>2, job_name=>'YOUR_JOB_NAME');

Saturday, October 19, 2013

How to use the dbms_scheduler package to collect intermittent statistics on volatile tables

In the following example I am using the dbms_scheduler package to analyze certain volatile tables every hour:

BEGIN
  SYS.DBMS_SCHEDULER.CREATE_JOB
    (
       job_name        => 'GATHERSTATS'
      ,start_date      => TO_TIMESTAMP_TZ('2009/05/13 12:17:57.508450 +02:00','yyyy/mm/dd hh24:mi:ss.ff tzh:tzm')
      ,repeat_interval => 'FREQ=HOURLY;'
      ,end_date        => NULL
      ,job_class       => 'DEFAULT_JOB_CLASS'
      ,job_type        => 'PLSQL_BLOCK'
      ,job_action      => '
                            begin
                            dbms_stats.gather_table_stats( 
                            ownname=> ''TBR'', 
                            tabname=> ''LOGONS'' , 
                            estimate_percent=> DBMS_STATS.AUTO_SAMPLE_SIZE,  
                            cascade=> DBMS_STATS.AUTO_CASCADE, 
                            degree=> null,  
                            no_invalidate=> DBMS_STATS.AUTO_INVALIDATE, 
                            granularity=> ''AUTO'', 
                            method_opt=> ''FOR ALL COLUMNS SIZE AUTO'');
                            comments=>'your comment here'
END;
/