dbms_scheduler

Copying Oracle Scheduler jobs with Arguments

Oracle provides dbms_scheduler.copy_job function to copy oracle scheduler jobs which works great. But problem is that it cannot copy  jobs which have  arguments.

Need to copy jobs can arise due to following scenarios

1)Runaway jobs – When Scheduler job is running without any SID. This means OS session is not present and this will not clear. These jobs have to be recreated to resolve the issue.
2)Jobs can not be stopped – many times jobs cannot be stopped by dbms_scheduler.stop_job(<jobname>,true) as they error out with “Internal error”
3)We need to have similar job but under different schema or with different name

I have written below code which would prompt for username and jobname and will copy the job along with its arguments

declare
l_owner varchar2(30) :='&job_owner';
l_old_job varchar2(30) :='&job_name';
l_new_job varchar2(30);
cnt integer;
cursor c_arg is select argument_position,value from DBA_SCHEDULER_JOB_ARGS where job_name = l_old_job and owner = l_owner order by argument_position;
begin
l_new_job :='INTERMEDIATE_CPY';
select count(*) into cnt from dba_scheduler_jobs where job_name = l_new_job and owner = l_owner;
		if ( cnt > 0 ) then
			dbms_output.put_line ('dropping scheduler job INTERMEDIATE_CPY');
			 dbms_scheduler.drop_job(l_owner||'.'||l_new_job,true);
			end if;
sys.dbms_scheduler.copy_job(l_owner||'.'||l_old_job,l_owner||'.'||l_new_job);
sys.dbms_scheduler.drop_job(l_owner||'.'||l_old_job,true);
sys.dbms_scheduler.copy_job(l_owner||'.'||l_new_job,l_owner||'.'||l_old_job);
for v_arg in c_arg
	loop
		dbms_output.put_line('Setting ARGUMENT_POSITION '||v_arg.argument_position||' to value '||v_arg.value);
	 sys.dbms_scheduler.set_job_argument_value(job_name =>l_owner||'.'||l_old_job,ARGUMENT_POSITION=>v_arg.argument_position,ARGUMENT_VALUE =>v_arg.value);
	 end loop;
	 sys.dbms_scheduler.enable(l_owner||'.'||l_old_job);
	sys.dbms_scheduler.drop_job(l_owner||'.'||l_new_job,true);
end;
/

In case you don’t copy the arguments, jobs will fail with status as STOPPED and give REASON as “Job slave process was terminated”. Also it can generate following ORA-07445 error

ORA-07445: exception encountered: core dump [kpubsuuc()+197] [SIGSEGV] [Address not mapped to object] [0x000000000] [] []

User Sessions stuck on resmgr:cpu quantum wait event

We were experiencing lot of session getting stuck on resmgr:cpu quantum in our database.
In fact at a time we had 70 sessions which were stuck on this wait event and our cpu load average was touching 60

Checking active resource plan, we found that DEFAULT_MAINTENANCE_PLAN was active. As per 11g Docs

In this plan, any sessions in the SYS_GROUP consumer group get priority. (Sessions in this group are sessions created by user accounts SYS and SYSTEM.) Any resource allocation that is unused by sessions in SYS_GROUP is then shared by sessions belonging to the other consumer groups and subplans in the plan. Of that allocation, 25% goes to maintenance tasks, 5% goes to background processes performing diagnostic operations, and 70% goes to user sessions. To reduce or increase resource allocation to the automated maintenance tasks, you make adjustments to DEFAULT_MAINTENANCE_PLAN.

These plans are associated to 11g windows like MONDAY_WINDOW. You can check it using following query

col window_name format a17
col RESOURCE_PLAN format a25
col LAST_START_DATE format a50
col duration format a15
col enabled format a5
select window_name, RESOURCE_PLAN, LAST_START_DATE, DURATION, enabled from DBA_SCHEDULER_WINDOWS;

WINDOW_NAME	  RESOURCE_PLAN 	    LAST_START_DATE				       DURATION        ENABL
----------------- ------------------------- -------------------------------------------------- --------------- -----
MONDAY_WINDOW	  DEFAULT_MAINTENANCE_PLAN  16-JAN-12 10.00.00.007154 PM PST8PDT	       +000 04:00:00   TRUE
TUESDAY_WINDOW	  DEFAULT_MAINTENANCE_PLAN  10-JAN-12 10.00.00.002781 PM PST8PDT	       +000 04:00:00   TRUE
WEDNESDAY_WINDOW  DEFAULT_MAINTENANCE_PLAN  11-JAN-12 10.00.00.008333 PM PST8PDT	       +000 04:00:00   TRUE
THURSDAY_WINDOW   DEFAULT_MAINTENANCE_PLAN  12-JAN-12 10.00.00.011284 PM PST8PDT	       +000 04:00:00   TRUE
FRIDAY_WINDOW	  DEFAULT_MAINTENANCE_PLAN  13-JAN-12 10.00.00.010937 PM PST8PDT	       +000 04:00:00   TRUE
SATURDAY_WINDOW   DEFAULT_MAINTENANCE_PLAN  14-JAN-12 06.00.00.146968 AM PST8PDT	       +000 20:00:00   TRUE
SUNDAY_WINDOW	  DEFAULT_MAINTENANCE_PLAN  15-JAN-12 06.00.00.003916 AM PST8PDT	       +000 20:00:00   TRUE
WEEKNIGHT_WINDOW									       +000 08:00:00   FALSE
WEEKEND_WINDOW										       +002 00:00:00   FALSE

 

You can disable the resource_plan by using following commands

execute dbms_scheduler.set_attribute('MONDAY_WINDOW','RESOURCE_PLAN','');
execute dbms_scheduler.set_attribute('TUESDAY_WINDOW','RESOURCE_PLAN','');
execute dbms_scheduler.set_attribute('WEDNESDAY_WINDOW','RESOURCE_PLAN','');
execute dbms_scheduler.set_attribute('THURSDAY_WINDOW','RESOURCE_PLAN','');
execute dbms_scheduler.set_attribute('FRIDAY_WINDOW','RESOURCE_PLAN','');
execute dbms_scheduler.set_attribute('SATURDAY_WINDOW','RESOURCE_PLAN','');
execute dbms_scheduler.set_attribute('SUNDAY_WINDOW','RESOURCE_PLAN','');

Verify that resource_plan is disabled

select window_name, RESOURCE_PLAN, LAST_START_DATE, DURATION, enabled from DBA_SCHEDULER_WINDOWS;

WINDOW_NAME	  RESOURCE_PLAN 	    LAST_START_DATE				       DURATION        ENABL
----------------- ------------------------- -------------------------------------------------- --------------- -----
MONDAY_WINDOW				    16-JAN-12 10.00.00.007154 PM PST8PDT	       +000 04:00:00   TRUE
TUESDAY_WINDOW				    10-JAN-12 10.00.00.002781 PM PST8PDT	       +000 04:00:00   TRUE
WEDNESDAY_WINDOW			    11-JAN-12 10.00.00.008333 PM PST8PDT	       +000 04:00:00   TRUE
THURSDAY_WINDOW 			    12-JAN-12 10.00.00.011284 PM PST8PDT	       +000 04:00:00   TRUE
FRIDAY_WINDOW				    13-JAN-12 10.00.00.010937 PM PST8PDT	       +000 04:00:00   TRUE
SATURDAY_WINDOW 			    14-JAN-12 06.00.00.146968 AM PST8PDT	       +000 20:00:00   TRUE
SUNDAY_WINDOW				    15-JAN-12 06.00.00.003916 AM PST8PDT	       +000 20:00:00   TRUE
WEEKNIGHT_WINDOW									       +000 08:00:00   FALSE
WEEKEND_WINDOW										       +002 00:00:00   FALSE

I was not concerned about automated tasks taking more cpu as it was already disabled using

execute DBMS_AUTO_TASK_ADMIN.DISABLE;