150 DBMS_SCHEDULER
The DBMS_SCHEDULER
package provides a collection of scheduling functions and procedures that can be called from any PL/SQL program.
This chapter contains the following topics:
See Also:
Oracle Database Administrator's Guide for more information regarding how to use DBMS_SCHEDULER
150.1 DBMS_SCHEDULER Deprecated Subprograms
Oracle recommends that you do not use deprecated subprograms in new applications. Support for deprecated features is for backward compatibility only
The following subprograms are deprecated with Oracle Database 12c Release 1 (12.1):
150.2 DBMS_SCHEDULER Security Model
The DBMS_SCHEDULER
package ignores privileges granted on scheduler objects, such as jobs or chains, through roles. Object privileges must be granted directly to the user.
150.3 DBMS_SCHEDULER Rules and Limits
These rules apply when using the DBMS_SCHEDULER
package.
-
Only
SYS
can perform actions on objects in theSYS
schema. -
Several of the procedures accept comma-delimited lists of object names. If you provide a list of names, then the Scheduler stops executing the list at the first object that returns an error. Therefore, the Scheduler does not perform the tasks needed for the remaining objects on the list.
For example, consider the statement
DBMS_SCHEDULER.STOP_JOB ('job1, job2, job3, sys.jobclass1, sys.jobclass2, sys.jobclass3');
If
job3
cannot be stopped, then the jobs that follow it,jobclass1
,jobclass2
, andjobclass3
cannot be stopped. The jobs that precededjob3
,job1
andjob2
, are stopped. -
Performing an action on an object that does not exist returns a PL/SQL exception stating that the object does not exist.
150.4 DBMS_SCHEDULER Operational Notes
The Scheduler uses a rich calendaring syntax to enable you to define repeating schedules, such as "every Tuesday and Friday at 4:00 p.m." or "the second Wednesday of every month." This calendaring syntax is used in calendaring expressions in the repeat_interval
argument of a number of package subprograms. Evaluating a calendaring expression results in a set of discrete timestamps.
See Oracle Database Administrator's Guide for examples of the calendaring syntax.
Calendaring Syntax
This section starts with the calendaring syntax. It is followed by descriptions of various parts of the syntax.
In the calendaring syntax, * means 0 or more.
repeat_interval = regular_schedule | combined_schedule regular_schedule = frequency_clause [";" interval_clause] [";" bymonth_clause] [";" byweekno_clause] [";" byyearday_clause] [";" bydate_clause] [";" bymonthday_clause] [";" byday_clause] [";" byhour_clause] [";" byminute_clause] [";" bysecond_clause] [";" bysetpos_clause] [";" include_clause] [";" exclude_clause] [";" intersect_clause][";" periods_clause] [";" byperiod_clause]
frequency_clause = "FREQ" "=" ( predefined_frequency | user_defined_frequency ) predefined_frequency = "YEARLY" | "MONTHLY" | "WEEKLY" | "DAILY" | "HOURLY" | "MINUTELY" | "SECONDLY" user_defined_frequency = named_schedule interval_clause = "INTERVAL" "=" intervalnum intervalnum = 1 through 99 bymonth_clause = "BYMONTH" "=" monthlist monthlist = month ( "," month)* month = numeric_month | char_month numeric_month = 1 | 2 | 3 ... 12 char_month = "JAN" | "FEB" | "MAR" | "APR" | "MAY" | "JUN" | "JUL" | "AUG" | "SEP" | "OCT" | "NOV" | "DEC" byweekno_clause = "BYWEEKNO" "=" weeknumber_list weeknumber_list = weeknumber ( "," weeknumber)* weeknumber = [minus] weekno weekno = 1 through 53 byyearday_clause = "BYYEARDAY" "=" yearday_list yearday_list = yearday ( "," yearday)* yearday = [minus] yeardaynum yeardaynum = 1 through 366 bydate_clause = "BYDATE" "=" date_list date_list = date ( "," date)* date = [YYYY]MMDD [ offset | span ] bymonthday_clause = "BYMONTHDAY" "=" monthday_list monthday_list = monthday ( "," monthday)* monthday = [minus] monthdaynum monthdaynum = 1 through 31 byday_clause = "BYDAY" "=" byday_list byday_list = byday ( "," byday)* byday = [weekdaynum] day weekdaynum = [minus] daynum daynum = 1 through 53 /* if frequency is yearly */ daynum = 1 through 5 /* if frequency is monthly */ day = "MON" | "TUE" | "WED" | "THU" | "FRI" | "SAT" | "SUN" BYTIME clause: BYTIME=[hour_minute_second_list|minute_second_list] hour_minute_second_list: hh24mmss, .., hh24mmss minute_second_list: mmss, .. mmss byhour_clause = "BYHOUR" "=" hour_list hour_list = hour ( "," hour)* hour = 0 through 23 byminute_clause = "BYMINUTE" "=" minute_list minute_list = minute ( "," minute)* minute = 0 through 59 bysecond_clause = "BYSECOND" "=" second_list second_list = second ( "," second)* second = 0 through 59 bysetpos_clause = "BYSETPOS" "=" setpos_list setpos_list = setpos ("," setpos)* setpos = [minus] setpos_num setpos_num = 1 through 9999 include_clause = "INCLUDE" "=" schedule_list exclude_clause = "EXCLUDE" "=" schedule_list intersect_clause = "INTERSECT" "=" schedule_list schedule_list = schedule_clause ("," schedule_clause)* schedule_clause = named_schedule [ offset ] named_schedule = [schema "."] schedule periods_clause = "PERIODS" "=" periodnum byperiod_clause = "BYPERIOD" "=" period_list period_list = periodnum ("," periodnum)* periodnum = 1 through 100 offset = ("+" | "-") ["OFFSET:"] duration_val span = ("+" | "-" | "^") "SPAN:" duration_val duration_val = dur-weeks | dur_days dur_weeks = numofweeks "W" dur_days = numofdays "D" numofweeks = 1 through 53 numofdays = 1 through 376 minus = "-" combined_schedule = schedule_list
Table 150-1 Values for repeat_interval
Name | Description |
---|---|
|
This specifies the type of recurrence. It must be specified. The possible predefined frequency values are YEARLY, MONTHLY, WEEKLY, DAILY, HOURLY, MINUTELY, and SECONDLY. Alternatively, specifies an existing schedule to use as a user-defined frequency. |
|
This specifies a positive integer representing how often the recurrence repeats. The default is 1, which means every second for secondly, every day for daily, and so on. The maximum value is 99. |
|
This specifies which month or months you want the job to execute in. You can use numbers such as 1 for January and 3 for March, as well as three-letter abbreviations such as FEB for February and JUL for July. |
|
This specifies the week of the year as a number. It follows ISO-8601, which defines the week as starting with Monday and ending with Sunday; and the first week of a year as the first week, which is mostly within the Gregorian year. The first week is equivalent to the following two variants: the week that contains the first Thursday of the Gregorian year; and the week containing January 4th. The ISO-8601 week numbers are integers from 1 to 52 or 53; parts of week 1 may be in the previous calendar year; parts of week 52 may be in the following calendar year; and if a year has a week 53, parts of it must be in the following calendar year. As an example, in the year 1998, the ISO week 1 began on Monday December 29th, 1997; and the last ISO week (week 53) ended on Sunday January 3rd, 1999. So December 29th, 1997, is in the ISO week 1998-01, and January 1st, 1999, is in the ISO week 1998-53.
Examples of invalid specifications are |
|
This specifies the day of the year as a number. Valid values are 1 to 366. An example is 69, which is March 10 (31 for January, 28 for February, and 10 for March). 69 evaluates to March 10 for non-leap years and March 9 in leap years. -2 will always evaluate to December 30th independent of whether it is a leap year. |
|
This specifies a list of dates, where each date is of the form
The following
The plus sign in front of the Offsets adjust the supplied date by adding or subtracting |
|
This specifies the day of the month as a number. Valid values are 1 to 31. An example is 10, which means the 10th day of the selected month. You can use the minus sign (-) to count backward from the last day, so, for example, |
|
This specifies the day of the week from Monday to Sunday in the form MON, TUE, and so on. Using numbers, you can specify the 26th Friday of the year, if using a YEARLY frequency, or the 4th THU of the month, using a MONTHLY frequency. Using the minus sign, you can say the second to last Friday of the month. For example, |
|
This specifies the hour on which the job is to run. Valid values are 0 to 23. As an example, 10 means 10 a.m. |
|
This specifies the minute on which the job is to run. Valid values are 0 to 59. As an example, 45 means 45 minutes past the chosen hour. |
|
This specifies the second on which the job is to run. Valid values are 0 to 59. As an example, 30 means 30 seconds past the chosen minute. |
|
This selects one or more items, by position, in the list of timestamps that result after the whole calendaring expression is evaluated. It is useful for requirements such as running a job on the last workday of the month. Rather than attempting to express this with the other FREQ=MONTHLY; BYDAY=MON,TUE,WED,THU,FRI; BYSETPOS=-1 Valid values are 1 through 9999. A negative number selects an item from the end of the list (-1 is the last item, -2 is the next to last item, and so on) and a positive number selects from the front of the list. The The |
|
This includes one or more named schedules in the calendaring expression. That is, the set of timestamps defined by each included named schedule is added to the results of the calendaring expression. If an identical timestamp is contributed by both an included schedule and the calendaring expression, it is included in the resulting set of timestamps only once. The named schedules must have been defined with the This clause only works on a full day and therefore cannot be used with |
|
This excludes one or more named schedules from the calendaring expression. That is, the set of timestamps defined by each excluded named schedule is removed from the results of the calendaring expression. The named schedules must have been defined with the This clause only works on a full day and therefore cannot be used with |
|
This specifies an intersection between the calendaring expression results and the set of timestamps defined by one or more named schedules. Only the timestamps that appear both in the calendaring expression and in one of the named schedules are included in the resulting set of timestamps. For example, assume that the named schedule 3/31/2005, 6/30/2005, 9/30/2005, 12/31/2005 These calendaring expressions result in the dates that follow: 3/31/2005, 4/30/2005, 6/30/2005, 9/30/2005, 12/31/2005 FREQ=MONTHLY; BYMONTHDAY=-1; INTERSECT=last_sat,end_qtr In this example, the terms This clause only works on a full day and therefore cannot be used with |
|
This identifies the number of periods that together form one cycle of a user-defined frequency. It is used in the FREQ=YEARLY;BYDATE=0301,0601,0901,1201;PERIODS=4 |
|
This selects periods from a user-defined frequency. For example, if a main schedule names a user-defined frequency schedule that defines the fiscal quarters shown in the previous example, the clause |
Combining Schedules
There are two ways to combine schedules:
-
Using a combined schedule expression, which is a list of individual schedules
For example, to create a schedule for all company holidays, you provide a list of individual schedules, where each schedule in the list defines a single holiday. The Scheduler evaluates each individual schedule, and then returns a union of the timestamps returned by each individual schedule.
-
Embedding other schedules into the main schedule using
include
,exclude
, andintersect
clausesWith this method, the embedded schedules inherit certain attributes from the main schedule.
-
Timestamps generated by the
INCLUDE
clause that fall into periods that are skipped by the main schedule are ignored. This is the case when the main schedule skips periods due to theINTERVAL
clause, theBYPERIOD
clause, or theBYMONTH
clause forfreq=monthly
. -
Days that are added by the
INCLUDE
clause follow the hourly/minutely/secondly execution pattern of the main schedule. -
When the
INCLUDE
clause is present, no date-specific defaults are retrieved from the start date (but time-specific defaults can be). (See "Start Dates and Repeat Intervals", later in this section.) For example, arepeat_interval
ofFREQ=MONTHLY;INCLUDE=HOLIDAY
executes only on holidays and not on the month/day defaults retrieved from the start date.
The following is an example:
BEGIN dbms_scheduler.create_schedule('embed_sched', repeat_interval => 'FREQ=YEARLY;BYDATE=0130,0220,0725'); dbms_scheduler.create_schedule('main_sched', repeat_interval => 'FREQ=MONTHLY;INTERVAL=2;BYMONTHDAY=15;BYHOUR=9,17;INCLUDE=embed_sched'); END; /
In this example, the dates 1/30, 2/20, and 7/25 are added to the main schedule. However, the Scheduler does not include dates that fall in months that are skipped by the
INTERVAL
clause. If the start date of the main schedule is 1/1/2005, then 2/20 is not added. On the dates that are added, the embedded schedule follows the execution pattern of the main schedule: jobs are executed at 9:00 a.m. and 5:00 p.m. on 1/30 and 7/25. If the embedded schedule does not itself have a start date, it inherits the start date from the main schedule. -
User-Defined Frequencies
Instead of using predefined frequencies like DAILY
, WEEKLY
, MONTHLY
, and so on, you can create your own frequencies by creating a schedule that returns the start date of each period. For example, the following repeat_interval
expression is used in a schedule named fiscal_year
that defines the start of each quarter in a fiscal year:
FREQ=YEARLY;BYDATE=0301,0601,0901,1201;PERIODS=4
To return the last Wednesday of every quarter, you create a schedule (the "main schedule") that uses the fiscal_year
schedule as a user-defined frequency:
FREQ=fiscal_year;BYDAY=-1WED
Periods in a user-defined frequency do not have to be equal in length. In the main schedule, the BYSETPOS
clause and numbered weekdays are recalculated based on the size of each period. To select dates in specific periods, you must use the BYPERIOD
clause in the main schedule. To enable this, the schedule that is used as the user-defined frequency must include a PERIODS
clause, and it must set its start date appropriately. The first date returned by this schedule is used as the starting point of period 1.
As another example, assuming work days are Monday through Friday, to get the last work day of the 2nd and 4th quarters of the fiscal year, the repeat_interval
clause in the main schedule is the following:
FREQ=fiscal_year;BYDAY=MON,TUE,WED,THU,FRI;BYPERIOD=2,4;BYSETPOS=-1
Start Dates and Repeat Intervals
The Scheduler retrieves the date and time from the job or schedule start date and incorporates them as defaults into the repeat_interval
. For example, if the specified frequency is yearly and there is no BYMONTH
or BYMONTHDAY
clause in the repeat interval, then the month and day that the job runs on are retrieved from the start date. Similarly, if frequency is monthly but there is no BYMONTHDAY
clause in the repeat interval, then the day of the month that the job runs on is retrieved from the start date. If present, BYHOUR
, BYMINUTE
, and BYSECOND
defaults are also retrieved from the start date, and used if those clauses are not specified. Note that if the INCLUDE
, EXCLUDE
, or INTERSECT
clauses are present, no date-related defaults are retrieved from the start date, but time-related defaults are.The following are some examples:
start_date: 4/15/05 9:00:00 repeat_interval: freq=yearly
is expanded internally to:
freq=yearly;bymonth=4;bymonthday=15;byhour=9;byminute=0;bysecond=0
The preceding schedule executes on 04/15/05 9:00:00, 04/15/06 9:00:00, 04/15/07 9:00:00, and so on.
For the next example, assume that schedule S1
has a repeat_interval
of FREQ=YEARLY;BYDATE=0701
.
start_date: 01/20/05 9:00:00 repeat_interval: freq=yearly;include=S1
is expanded internally to:
freq=yearly;byhour=9;byminute=0;bysecond=0;include=S1
Because an INCLUDE
clause is present, date-related information is not retrieved from the start date. However, time-specific information is, so the preceding schedule executes on 07/01/05 9:00:00, 07/01/06 9:00:00, 07/01/08 9:00:00, and so on.
General Rules
When using a calendaring expression, consider the following rules:
-
For a regular schedule (as opposed to a combined schedule), the calendar string must start with the frequency clause. All other clauses are optional and can be put in any order.
-
All clauses are separated by a semicolon, and each clause can be present at most once, with the exception of the
include
,exclude
, andintersect
clauses. -
Spaces are allowed between syntax elements and the strings are case-insensitive.
-
The list of values for a specific
BY
clause do not need to be ordered. -
When not enough
BY
clauses are present to determine what the next date is, this information is retrieved from the start date. For example,"FREQ=YEARLY"
with a start date of 02/15/2003 becomes"FREQ=YEARLY;BYMONTH=FEB; BYMONTHDAY=15"
, which means every year on the 15th of February."FREQ=YEARLY;BYMONTH=JAN,JUL"
with start date 01/21/2003 becomes"FREQ=YEARLY;BYMONTH=JAN,JUL;BYMONTHDAY=21",
which means every year on January 21 and July 21. -
The
byweekno
clause is only allowed if the frequency isYEARLY
. It cannot be used with other frequencies. When it is present, it will return all days in that week number. If you want to limit it to specific days within the week, you have to add aBYDAY
clause. For example,"FREQ=YEARLY;BYWEEKNO=2"
with a start date of 01/01/2003 will return:01/06/2003, 01/07/2003, 01/08/2003, 01/09/2003, 01/10/2003, 01/11/2003, 01/12/2003, 01/05/2004, 01/06/2004, 01/07/2004, .... and so on.
Note that when the
byweekno
clause is used, it is possible that the dates returned are from a year other than the current year. For example, if returning dates for the year 2004 and the calendar string is"FREQ=YEARLY;BYWEEKNO=1,53"
for the specified week numbers in 2004, it will return the dates:12/29/03, 12/30/03, 12/31/03, 01/01/04, 01/02/04, 01/03/04, 01/04/04, 12/27/04, 12/28/04, 12/29/04, 12/30/04, 12/31/04, 01/01/05, 01/02/05
-
For those
BY
clauses that do not have a consistent range of values, you can count backward by putting a "-" in front of the numeric value. For example, specifyingBYMONTHDAY=31
will not give you the last day of every month, because not every month has 31 days. Instead,BYMONTHDAY=-1
will give you the last day of the month.This is not supported for
BY
clauses that are fixed in size. In other words,BYMONTH
,BYHOUR
,BYMINUTE
, andBYSECOND
are not supported. -
The basic values for the
BYDAY
clause are the days of the week. When the frequency isYEARLY
, orMONTHLY
, you are allowed to specify a positive or negative number in front of each day of the week. In the case ofYEARLY
,BYDAY=40MON
, indicates the 40th Monday of the year. In the case ofMONTHLY, BYDAY=-2SAT
, indicates the second to last Saturday of the month.Note that positive or negative numbers in front of the weekdays are not supported for other frequencies and that in the case of yearly, the number ranges from -53 ... -1, 1 ... 53, whereas for the monthly frequency it is limited to -5 ... -1, 1... 5.
If no number is present in front of the weekday it specifies, every occurrence of that weekday in the specified frequency.
-
The first day of the week is Monday.
-
Repeating jobs with frequencies smaller than daily follow their frequencies exactly across daylight savings adjustments. For example, suppose that a job is scheduled to repeat every 3 hours, the clock is moved forward from 1:00 a.m. to 2:00 a.m., and the last time the job ran was midnight. Its next scheduled time will be 4:00 a.m. Thus, the 3 hour period between subsequent job runs is retained. The same applies when the clock is moved back. This behavior is not the case for repeating jobs that have frequencies of daily or larger. For example, if a repeating job is supposed to be executed on a daily basis at midnight, it will continue to run at midnight if the clock is moved forward or backward. When the execution time of such a daily (or larger frequency) job happens to fall inside a window where the clock is moved forward, the job executes at the end of the window.
-
The calendaring syntax does not allow you to specify a time zone. Instead the Scheduler retrieves the time zone from the
start_date
argument. If jobs must follow daylight savings adjustments, then you must specify a region name for the time zone of thestart_date
. For example specifying thestart_date
time zone as 'US/Eastern
' in New York ensures that daylight saving adjustments are automatically applied. If instead, the time zone of thestart_date
is set to an absolute offset, such as '-5:00
', then daylight savings adjustments are not followed and your job execution is off by an hour for half the year. -
When
start_date
isNULL
, the Scheduler determines the time zone for the repeat interval as follows:-
It checks whether or not the session time zone is a region name. The session time zone can be set by either:
-
Issuing an
ALTER
SESSION
statement, for example:SQL> ALTER SESSION SET time_zone = 'Asia/Shanghai';
-
Setting the
ORA_SDTZ
environment variable.
-
-
If the session time zone is an absolute offset instead of a region name, the Scheduler uses the value of the
DEFAULT_TIMEZONE
Scheduler attribute. For more information, see the SET_SCHEDULER_ATTRIBUTE Procedure. -
If the
DEFAULT_TIMEZONE
attribute isNULL
, the Scheduler uses the time zone ofsystimestamp
when the job or window is enabled.
-
BYSETPOS Clause Rules
The following are rules for the BYSETPOS
clause.
-
The
BYSETPOS
clause is the last clause to be evaluated. It is processed after all otherBY
clauses and theINCLUDE
,EXCLUDE
andINTERSECT
clauses have been evaluated. -
The
INTERVAL
clause does not change the size of the period to which theBYSETPOS
clause is applied. For example, when the frequency is set to monthly and interval is set to 3, the list of timestamps to whichBYSETPOS
is applied is generated from a month, not a quarter. The only impact of theINTERVAL
clause is to cause months to be skipped. However, you can still select the second to last workday of the quarter like this:FREQ=MONTHLY;INTERVAL=3;BYDAY=MON,TUE,WED,THU,FRI;BYSETPOS=-2
provided that you set the start date in the right month. This example returns the next to last workday of a month, and repeats once a quarter.
-
To get consistent results, the set to which
BYSETPOS
is applied is determined from the beginning of the frequency period independently of when the evaluation occurs. Whether the Scheduler evaluatesFREQ=MONTHLY;BYDAY=MON,TUE,FRI;BYSETPOS=1,3
on 01/01/2004 or 01/15/2004, in both cases the expression evaluates to Friday 01/02/2004, and Tuesday 01/06/2004. The only difference is that when the expression is evaluated on 01/15/2004, the Scheduler determines that there are no matches in January because the timestamps found are in the past, and it moves on to the matches in the next month, February.
BYDATE Clause Rules
The following are rules for the BYDATE
clause.
-
If dates in the
BYDATE
clause do not have their optional year component, the job runs on those dates every year. -
The job execution times on the included dates are derived from the
BY
clauses in the calendaring expression. For example, ifrepeat_interval
is defined asfreq=daily;byhour=8,13,18;byminute=0;bysecond=0;bydate=0502,0922
then the execution times on 05/02 and 09/22 are 8:00 a.m., 1:00 p.m., and 6:00 p.m.
EXCLUDE Clause Rules
Excluded dates without a time component are 24 hour periods. All timestamps that fall on an excluded date are removed. In the following example, jan_fifteen
is a named schedule that resolves to the single date of 01/15:
freq=monthly;bymonthday=15,30;byhour=8,13,18;byminute=0;bysecond=0; exclude=jan_fifteenth
In this case, all three instances of the job are removed for 01/15.
OFFSET Rules
You can adjust the dates of individual named schedules by adding positive offsets to them. For example, to execute JOB2
exactly 15 days after every occurrence of JOB1
, add +OFFSET:15D
to the schedule of JOB1
, as follows:
BEGIN dbms_scheduler.create_schedule('job2_schedule', repeat_interval => 'job1_schedule+OFFSET:15D'); END; /
Note that negative offsets to named schedules are not supported.
Example 150-1 Putting It All Together
This example demonstrates the use of user-defined frequencies, spans, offsets, and the BYSETPOS
and INCLUDE
clauses. (Note that the OFFSET:
keyword is optional in an offset clause.)
Many companies in the retail industry share the same fiscal year. The fiscal year starts on the Sunday closest to February 1st, and subsequent quarters start exactly 13 weeks later. The fiscal year schedule for the retail industry can be defined as the following:
begin dbms_scheduler.create_schedule('year_start', repeat_interval=> 'FREQ=YEARLY;BYDATE=0201^SPAN:1W;BYDAY=SUN'); dbms_scheduler.create_schedule('retail_fiscal_year', to_timestamp_tz('15-JAN-2005 12:00:00','DD-MON-YYYY HH24:MI:SS'), 'year_start,year_start+13w,year_start+26w,year_start+39w;periods=4'); end; /
The following schedule can be used to execute a job on the 5th day off in the 2nd and the 4th quarters of the retail industry. This assumes that Saturday and Sunday are off days as well as the days in the existing holiday
schedule.
begin dbms_scheduler.create_schedule('fifth_day_off', repeat_interval=> 'FREQ=retail_fiscal_year;BYDAY=SAT,SUN;INCLUDE=holiday; BYPERIOD=2,4;BYSETPOS=5'); end; /
150.5 DBMS_SCHEDULER Data Structures
The DBMS_SCHEDULER
package defines OBJECT
types and TABLE
types.
OBJECT Types
150.5.1 DBMS_SCHEDULER JOBARG Object Type
This type is used by the JOB
and JOBATTR
object types. It represents a job argument in a batch of job arguments.
Syntax
TYPE jobarg IS OBJECT ( arg_position NUMBER, arg_text_value VARCHAR2(4000), arg_anydata_value ANYDATA, arg_operation VARCHAR2(5));
Attributes
Table 150-2 JOBARG Object Type Attributes
Attribute | Description |
---|---|
|
Position of the argument |
|
Value of the argument if the type is |
|
Value of the argument if the type is |
|
Type of the operation:
|
JOBARG Constructor Function
This constructor function constructs a job argument. It is overloaded to construct job arguments with different types of values.
Syntax
Constructs a job argument with a text value.
constructor function jobarg ( arg_position IN POSITIVEN, arg_value IN VARCHAR2) RETURN SELF AS RESULT;
Constructs a job argument with an AnyData
value.
constructor function jobarg ( arg_position IN POSITIVEN, arg_value IN ANYDATA) RETURN SELF AS RESULT;
Constructs a job argument with a NULL
value.
constructor function jobarg ( arg_position IN POSITIVEN, arg_reset IN BOOLEAN DEFAULT FALSE) RETURN SELF AS RESULT;
Parameters
Table 150-3 JOBARG Constructor Function Parameters
Parameter | Description |
---|---|
|
Position of the argument |
|
Value of the argument |
|
If Setting |
JOBARG_ARRAY Table Type
Syntax
TYPE jobarg_array IS TABLE OF jobarg;
150.5.2 JOBARG_ARRAY Table Type
The jobarg_array
type is a table of jobarg
.
Syntax
TYPE jobarg_array IS TABLE OF jobarg;
150.5.3 DBMS_SCHEDULER JOB_DEFINITION Object Type
This type is used by the CREATE_JOBS
procedure and represents a job in a batch of jobs.
Syntax
TYPE job_definition IS OBJECT ( job_name VARCHAR2(100), job_class VARCHAR2(32), job_style VARCHAR2(11), program_name VARCHAR2(100), job_action VARCHAR2(4000), job_type VARCHAR2(20), schedule_name VARCHAR2(65), repeat_interval VARCHAR2(4000), schedule_limit INTERVAL DAY TO SECOND, start_date TIMESTAMP WITH TIME ZONE, end_date TIMESTAMP WITH TIME ZONE, event_condition VARCHAR2(4000), queue_spec VARCHAR2(100), number_of_arguments NUMBER, arguments SYS.JOBARG_ARRAY, job_priority NUMBER, job_weight NUMBER, max_run_duration INTERVAL DAY TO SECOND, max_runs NUMBER, max_failures NUMBER, logging_level NUMBER, restartable VARCHAR2(5), stop_on_window_close VARCHAR2(5), raise_events NUMBER, comments VARCHAR2(240), auto_drop VARCHAR2(5), enabled VARCHAR2(5), follow_default_timezone VARCHAR2(5), parallel_instances VARCHAR2(5), aq_job VARCHAR2(5), instance_id NUMBER, credential_name VARCHAR2(65), destination VARCHAR2(4000), database_role VARCHAR2(20), allow_runs_in_restricted_mode VARCHAR2(5); restart_on_recovery BOOLEAN; restart_on_failure BOOLEAN;)
Object Attributes
Table 150-4 provides brief descriptions of the attributes of the JOB_DEFINITION
object type. For more complete information about these attributes, see the "CREATE_JOB Procedure" and the "SET_ATTRIBUTE Procedure".
Table 150-4 JOB_DEFINITION Object Types
Attribute | Description |
---|---|
|
Name of the job |
|
Name of the job class |
|
Style of the job:
|
|
Name of the program that the job runs |
|
Inline action of the job. This is either the code for an anonymous PL/SQL block or the name of a stored procedure, external executable, or chain. |
|
Job action type (' |
|
Name of the schedule that specifies when the job has to execute |
|
Inline time-based schedule |
|
Maximum delay time between scheduled and actual job start before a job run is canceled |
|
Start date and time of the job |
|
End date and time of the job |
|
Event condition for event-based jobs |
|
File watcher name or queue specification for event-based jobs |
|
Number of job arguments |
|
Array of job arguments |
|
Job priority |
|
*** Deprecated in Oracle Database 11gR2. Do not change the value of this attribute from the default, which is 1. Weight of the job for parallel execution. |
|
Maximum run duration of the job |
|
Maximum number of runs before the job is marked as completed |
|
Maximum number of failures tolerated before the job is marked as broken |
|
Job logging level |
|
Indicates whether the job is restartable ( |
|
Indicates whether the job is stopped when the window that it runs in ends ( |
|
State changes that raise events |
|
Comments on the job |
|
If |
|
Indicates whether the job should be enabled immediately after creating it ( |
|
If |
|
For event-based jobs only. If If |
|
For internal use only |
|
The instance ID of the instance that the job must run on For in-memory full jobs, the |
|
The credential to use for a single destination or the default credential for a group of destinations |
|
The name of a single external destination or database destination, or a group name of type external destination or database destination |
|
In an Oracle Data Guard environment, the database role (' |
|
If |
|
If set to If set to |
|
If set to If set to |
JOB_DEFINITION Constructor Function
This constructor function constructs a job_definition
object.
Syntax
constructor function job_definition ( job_name IN VARCHAR2, job_style IN VARCHAR2 DEFAULT 'REGULAR', program_name IN VARCHAR2 DEFAULT NULL, job_action IN VARCHAR2 DEFAULT NULL, job_type IN VARCHAR2 DEFAULT NULL, schedule_name IN VARCHAR2 DEFAULT NULL, repeat_interval IN VARCHAR2 DEFAULT NULL, event_condition IN VARCHAR2 DEFAULT NULL, queue_spec IN VARCHAR2 DEFAULT NULL, start_date IN TIMESTAMP WITH TIME ZONE DEFAULT NULL, end_date IN TIMESTAMP WITH TIME ZONE DEFAULT NULL, number_of_arguments IN NATURAL DEFAULT NULL, arguments IN SYS.JOBARG_ARRAY DEFAULT NULL, job_class IN VARCHAR2 DEFAULT 'DEFAULT_JOB_CLASS', schedule_limit IN INTERVAL DAY TO SECOND DEFAULT NULL, job_priority IN NATURAL DEFAULT NULL, job_weight IN NATURAL DEFAULT NULL, max_run_duration IN INTERVAL DAY TO SECOND DEFAULT NULL, max_runs IN NATURAL DEFAULT NULL, max_failures IN NATURAL DEFAULT NULL, logging_level IN NATURALN DEFAULT 64, restartable IN BOOLEAN DEFAULT FALSE, stop_on_window_close IN BOOLEAN DEFAULT FALSE, raise_events IN NATURAL DEFAULT NULL, comments IN VARCHAR2 DEFAULT NULL, auto_drop IN BOOLEAN DEFAULT TRUE, enabled IN BOOLEAN DEFAULT FALSE, follow_default_timezone IN BOOLEAN DEFAULT FALSE, parallel_instances IN BOOLEAN DEFAULT FALSE, aq_job IN BOOLEAN DEFAULT FALSE, instance_id IN NATURAL DEFAULT NULL, credential_name IN VARCHAR2 DEFAULT NULL, destination IN VARCHAR2 DEFAULT NULL, database_role IN VARCHAR2 DEFAULT NULL, allow_runs_in_restricted_mode IN BOOLEAN DEFAULT FALSE) RETURN SELF AS RESULT;
JOB_DEFINITION_ARRAY Table Type
Syntax
TYPE job_definition_array IS TABLE OF job_definition;
150.5.4 JOB_DEFINITION_ARRAY Table Type
The type job_definition_array
is a table of job_definition
.
Syntax
TYPE job_definition_array IS TABLE OF job_definition;
150.5.5 JOBATTR Object Type
This type is used by the SET_JOB_ATTRIBUTES
procedure and represents a job attribute in a batch of job attributes.
Syntax
TYPE jobattr IS OBJECT ( job_name VARCHAR2(100), attr_name VARCHAR2(30), char_value VARCHAR2(4000), char_value2 VARCHAR2(4000), args_value JOBARG_ARRAY, num_value NUMBER, timestamp_value TIMESTAMP(6) WITH TIME ZONE, interval_value INTERVAL DAY(2) TO SECOND(6));
Attributes
Table 150-5 JOBATTR Object Type Attributes
Attribute | Description |
---|---|
|
Name of the job |
|
Name of the attribute |
|
Value of the argument if the type is |
|
Second |
|
Value of the argument if the type is a |
|
Value of the argument if the type is |
|
Value of the argument if the type is |
|
Value of the argument if the type is |
JOBATTR Constructor Function
This constructor function constructs a job attribute. It is overloaded to create attribute values of the following types: VARCHAR2
, NUMBER
, TIMESTAMP WITH TIME ZONE
, INTERVAL DAY TO SECOND
, and an array of JOBARG
types.
Syntax
constructor function jobattr ( job_name IN VARCHAR2, attr_name IN VARCHAR2, attr_value IN VARCHAR2, attr_value2 IN VARCHAR2 DEFAULT NULL) RETURN SELF AS RESULT;
constructor function jobattr ( job_name IN VARCHAR2, attr_name IN VARCHAR2, attr_value IN [NUMBER, BOOLEAN, TIMESTAMP WITH TIME ZONE, INTERVAL DAY TO SECOND, JOBARG_ARRAY]) RETURN SELF AS RESULT;
constructor function jobattr ( job_name IN VARCHAR2, attr_name IN VARCHAR2) RETURN SELF AS RESULT;
Parameters
Table 150-6 JOBATTR Constructor Function Parameters
Parameter | Description |
---|---|
|
Name of the job |
|
Name of the argument |
|
Value of the argument |
|
Most attributes have only one value associated with them, but some can have two. The |
JOBATTR Table Type
Syntax
TYPE jobattr_array IS TABLE OF jobattr;
150.5.6 JOBATTR_ARRAY Table Type
The type jobattr_array
is a table of jobattr
.
Syntax
TYPE jobattr_array IS TABLE OF jobattr;
150.5.7 SCHEDULER$_STEP_TYPE Object Type
This type is used by RUN_CHAIN
to return a list of chain steps with an initial state.
Syntax
TYPE scheduler$_step_type IS OBJECT ( step_name VARCHAR2(32), step_type VARCHAR2(32));
Attributes
Table 150-7 SCHEDULER$_STEP_TYPE Object Type Attributes
Attribute | Description |
---|---|
|
Name of the step |
|
State of the step |
150.5.8 SCHEDULER$_STEP_TYPE_LIST Table Type
This type is a table of scheduler$_step_type
.
Syntax
TYPE scheduler$_step_type_list IS TABLE OF scheduler$_step_type;
150.5.9 SCHEDULER$_EVENT_INFO Object Type
This the datatype of the Scheduler event queue SYS.SCHEDULER$_EVENT_QUEUE
, from which your application consumes job state events raised by the Scheduler.
It is a secure queue owned by SYS
.
Syntax
TYPE SCHEDULER$_EVENT_INFO IS OBJECT ( event_type VARCHAR2(4000), object_owner VARCHAR2(4000), object_name VARCHAR2(4000), event_timestamp TIMESTAMP WITH TIME ZONE, error_code NUMBER, error_msg VARCHAR2(4000), event_status NUMBER, log_id NUMBER, run_count NUMBER, failure_count NUMBER, retry_count NUMBER, spare1 NUMBER, spare2 NUMBER, spare3 VARCHAR2(4000), spare4 VARCHAR2(4000), spare5 TIMESTAMP WITH TIME ZONE, spare6 TIMESTAMP WITH TIME ZONE, spare7 RAW(2000), spare8 RAW(2000));
Attributes
Table 150-8 SCHEDULER_EVENT_INFO Object Type Attributes
Attribute | Description |
---|---|
|
One of " For descriptions of these event types, see Table 150-84. |
|
Owner of the job that raised the event |
|
Name of the job that raised the event |
|
Time at which the event occurred |
|
Applicable only when an error is thrown during job execution. Contains the top-level error code. |
|
Applicable only when an error is thrown during job execution. Contains the entire error stack. |
|
Adds further qualification to the event type. If If If |
|
Points to the ID in the scheduler job log from which additional information can be obtained. Note that there need not always be a log entry corresponding to an event. In such cases, |
|
Run count for the job when the event was raised. |
|
Failure count for the job when the event was raised. |
|
Retry count for the job when the event was raised. |
|
Not currently in use. |
150.5.10 SCHEDULER_FILEWATCHER_RESULT Object Type
This is the datatype of a file arrival event message.
You access the event message as a parameter of an event-based job (or a parameter of a program referenced by an event-based job). The message contains information needed to locate and process a file that arrived on a local or remote system.
Syntax
TYPE scheduler_filewatcher_result IS OBJECT ( destination VARCHAR2(4000), directory_path VARCHAR2(4000), actual_file_name VARCHAR2(4000), file_size NUMBER, file_timestamp TIMESTAMP WITH TIME ZONE, ts_ms_from_epoch NUMBER, matching_requests SYS.SCHEDULER_FILEWATCHER_REQ_LIST);
Attributes
Table 150-9 SCHEDULER_FILEWATCHER_RESULT Object Type Attributes
Attribute | Description |
---|---|
|
Destination at which the file was found, expressed as a host name or IP address. |
|
Absolute path of directory in which the file was found. |
|
Actual name of the file that was found. If the file name specified in the file watcher did not contain wildcards, then this is the same as the name specified in the file watcher. |
|
Size of the file that was found, in bytes. |
|
Timestamp assigned to the file when the file watcher considered the file found, based on the minimum file size and steady state duration attributes. |
|
For internal use only. |
|
List of matching requests. This is a |
150.5.11 SCHEDULER_FILEWATCHER_REQUEST Object Type
This type is returned in the matching_requests
attribute of the SCHEDULER_FILEWATCHER_RESULT Object Type. Its attributes are similar to the attributes of a file watcher.
Syntax
TYPE scheduler_filewatcher_request IS OBJECT ( owner VARCHAR2(4000), name VARCHAR2(4000), requested_path_name VARCHAR2(4000), requested_file_name VARCHAR2(4000), credential_owner VARCHAR2(4000), credential_name VARCHAR2(4000), min_file_size NUMBER, steady_state_dur NUMBER);
Attributes
Table 150-10 SCHEDULER_FILEWATCHER_REQUEST Object Type Attributes
Attribute | Description |
---|---|
|
Owner of the matched file watcher. |
|
Name of the matched file watcher. |
|
Value of the |
|
Value of the |
|
Owner of the credential referenced by the matched file watcher. |
|
Name of the credential referenced by the matched file watcher. |
|
Value of the |
|
Value of the |
Related Topics
150.6 Summary of DBMS_SCHEDULER Subprograms
This table lists the DBMS_SCHEDULER
subprograms and briefly describes them.
Table 150-11 DBMS_SCHEDULER Package Subprograms
Subprogram | Description |
---|---|
Adds a user as a subscriber to the Scheduler event queue |
|
Adds one or more members to an existing group |
|
Adds e-mail notifications for a job for a list of recipients and a list of job state events |
|
Adds jobs or programs to an existing incompatibility definition |
|
Alters specified steps of a chain |
|
Alters specified steps of a running chain |
|
Closes an open window prematurely |
|
Copies an existing job |
|
Creates a chain, which is a named series of programs that are linked together for a combined objective |
|
Creates a credential |
|
Creates a database destination for use with remote database jobs |
|
Creates an event schedule, which is a schedule that starts a job based on the detection of an event |
|
Creates a file watcher, which is a Scheduler object that defines the location, name, and other properties of a file whose arrival on a system causes the Scheduler to start a job |
|
Creates a group |
|
Creates an incompatibility definition |
|
Creates a single job |
|
Creates a job class, which provides a way to group jobs for resource allocation and prioritization |
|
Creates multiple jobs |
|
Creates a program |
|
Specifies resources used by jobs or creates a new resource |
|
Creates a schedule |
|
Creates a window, which provides a way to automatically activate different resource plans at different times |
|
Defines a program argument whose value is of a complex type and must be passed encapsulated in an |
|
Adds or replaces a chain step and associates it with an event schedule or inline event. See also: |
|
Adds a rule to an existing chain |
|
Defines a chain step, which can be a program or another (nested) chain. See also: |
|
Defines a special metadata argument for the program. You can retrieve specific metadata through this argument. |
|
Defines a program argument whose value can be passed as a string literal to the program |
|
Disables a program, job, chain, window, database destination, external destination, file watcher, group, or incompatibilty |
|
Drops one or more external destinations. Use only when the preferred method of dropping external destinations—unregistering the Scheduler agent with the database—fails. |
|
Drops an existing chain |
|
Removes a rule from an existing chain |
|
Drops a chain step |
|
Drops a credential |
|
Drops one or more database destinations |
|
Drops one or more file watchers |
|
Drops one or more groups |
|
Drops an existing incompatibility definition |
|
Drops a job or all jobs in a job class |
|
Drops a job class |
|
Drops a program |
|
Drops a program argument |
|
Drops a schedule |
|
Drops a window |
|
Enables a program, job, chain, window, database destination, external destination, file watcher, or group |
|
Ends a running detached job |
|
Evaluates the calendar string and tells you what the next execution date of a job or window will be |
|
Forces reevaluation of the rules of a running chain to trigger any rules for conditions that have been satisfied |
|
Generates a unique name for a job. This enables you to identify jobs by adding a prefix, so, for example, Sally's jobs would be named |
|
Returns job information specific to an agent, such as how many are running and so on, depending on the attribute selected |
|
Returns the version string of a Scheduler agent that is registered with the database and is currently running |
|
Retrieves the value of an attribute of an object |
|
Retrieves a file from a host |
|
Retrieves the value of a Scheduler attribute |
|
Opens a window prematurely. The window is opened immediately for the duration |
|
Purges specific rows from the job and window logs |
|
Saves a file to one or more hosts |
|
Unsubscribes a user from the Scheduler event queue |
|
Removes jobs or programs from an incompatibility definition |
|
Removes one or more members from a group |
|
Removes e-mail notifications for a job |
|
Resets the current value assigned to an argument defined with the associated program |
|
Immediately runs a chain by creating a run-once job |
|
Runs a job immediately |
|
Sets the agent registration password for a database |
|
Changes an attribute of a job, schedule, or other Scheduler object |
|
Changes an attribute of an object to |
|
Sets the value of a job argument encapsulated in an |
|
Sets the value of a job argument |
|
Sets the value of a job attribute |
|
Specifies the resources used by jobs |
|
Sets the value of a Scheduler attribute |
|
Stops a currently running job or all jobs in a job class |
150.6.1 ADD_EVENT_QUEUE_SUBSCRIBER Procedure
This procedure adds a user as a subscriber to the Scheduler event queue SYS.SCHEDULER$_EVENT_QUEUE
, and grants the user permission to dequeue from this queue using the designated agent.
Syntax
DBMS_SCHEDULER.ADD_EVENT_QUEUE_SUBSCRIBER ( subscriber_name IN VARCHAR2 DEFAULT NULL);
Parameters
Table 150-12 ADD_EVENT_QUEUE_SUBSCRIBER Procedure Parameters
Parameter | Description |
---|---|
|
Name of the Oracle Advanced Queuing (AQ) agent to be used to subscribe to the Scheduler event queue. If |
Usage Notes
The subscription is rule-based. The rule permits the user to see only events raised by jobs that the user owns, and filters out all other messages. If an AQ agent with the same name already exists, an error is raised.
150.6.2 ADD_GROUP_MEMBER Procedure
This procedure adds one or more members to an existing group.
Syntax
DBMS_SCHEDULER.ADD_GROUP_MEMBER ( group_name IN VARCHAR2, member IN VARCHAR2);
Parameters
Table 150-13 ADD_GROUP_MEMBER Procedure Parameters
Parameter | Description |
---|---|
|
The name of the group. |
|
A comma-separated list of members to add to the group. Members must match the group type. A group of the same type can be a member. The Scheduler immediately expands the included group name into its list of members. An error is returned if any of the members do not exist. A member that is already in the group is skipped, and no error is generated. The keyword |
Usage Notes
The following users may add members to a group:
-
The group owner
-
A user that has been granted the
ALTER
object privilege on the group -
A user with the
CREATE ANY JOB
system privilege
You must have the MANAGE
SCHEDULER
privilege to add a member to a group of type WINDOW
.
See Also:
150.6.3 ADD_JOB_EMAIL_NOTIFICATION Procedure
This procedure adds e-mail notifications for a job. E-mails are then sent to the specified list of recipients whenever any of the specified job state events is raised.
Syntax
DBMS_SCHEDULER.ADD_JOB_EMAIL_NOTIFICATION ( job_name IN VARCHAR2, recipients IN VARCHAR2, sender IN VARCHAR2 DEFAULT NULL, subject IN VARCHAR2 DEFAULT DBMS_SCHEDULER.DEFAULT_NOTIFICATION_SUBJECT, body IN VARCHAR2 DEFAULT DBMS_SCHEDULER.DEFAULT_NOTIFICATION_BODY, events IN VARCHAR2 DEFAULT 'JOB_FAILED,JOB_BROKEN,JOB_SCH_LIM_REACHED, JOB_CHAIN_STALLED,JOB_OVER_MAX_DUR', filter_condition IN VARCHAR2 DEFAULT NULL);
Parameters
Table 150-14 ADD_JOB_EMAIL_NOTIFICATION Procedure Parameters
Parameter | Description |
---|---|
|
Name of the job that e-mail notifications are added for. Cannot be |
|
Comma-separated list of e-mail addresses to send notifications to. E-mail notifications for all listed events are sent to all recipients. Cannot be |
|
e-mail address to use as the sender address (the From: address) in the e-mail header. If |
|
The subject to use in the e-mail header. Table 150-15 describes the variables that you can include within this parameter. The Scheduler assigns values to these variables before sending the notification. If 'Oracle Scheduler Job Notification - %job_owner%.%job_name%.%job_subname% %event_type%' |
|
The body of the e-mail message. Table 150-15 describes the variables that you can include within this parameter. The Scheduler assigns values to these variables before sending the notification. If 'Job: %job_owner%.%job_name%.%job_subname% Event: %event_type% Date: %event_timestamp% Log id: %log_id% Job class: %job_class_name% Run count: %run_count% Failure count: %failure_count% Retry count: %retry_count% Error code: %error_code% Error message: %error_message%' |
|
Comma-separate list of job state events to send e-mail notifications for. Cannot be JOB_FAILED,JOB_BROKEN,JOB_SCH_LIM_REACHED,JOB_CHAIN_STALLED,JOB_OVER_MAX_DUR |
|
Used to filter events to send e-mail notifications for. If For example, to send an e-mail notification only when the error number in an event is 600 or 700, use the following :event.error_code=600 or :event.error_code=700 |
Table 150-15 lists the variables that you can use in the subject and body arguments.
Table 150-15 Variables Used in the SUBJECT and BODY Parameters
Variable | Comment |
---|---|
|
Schema in which job was created |
|
Name of the job that e-mail notifications are added for |
|
Present for event-based jobs with the |
|
Valid values are listed in Table 150-84 |
|
Time at which the event occurred |
|
Refers to the |
|
Number of the error code. |
|
The text of the error message |
|
Run count for the job when the event was raised |
|
Failure count for the job when the event was raised |
|
Retry count for the job when the event was raised |
Usage Notes
You can call ADD_JOB_EMAIL_NOTIFICATION
once for each different set of notifications that you want to configure for a particular job. For example, you may want to send notifications for the JOB_FAILED
, JOB_BROKEN
, JOB_SCH_LIM_REACHED
, and JOB_CHAIN_STALLED
events to the principle DBA and all senior DBAs, but send a notification for the JOB_OVER_MAX_DUR
event only to the principle DBA.
This procedure succeeds only if the Scheduler attribute email_server
is set to a valid SMTP server. See Oracle Database Administrator's Guide for more information.
To call this procedure, you must be the job owner or have the CREATE
ANY
JOB
system privilege or have the ALTER
object privilege on the job.
150.6.4 ADD_TO_INCOMPATIBILITY Procedure
This procedure adds jobs or programs to an existing incompatibility definition.
Syntax
DBMS_SCHEDULER.ADD_TO_INCOMPATIBILITY ( incompatibility_name IN VARCHAR2, object_name IN VARCHAR2);
Parameters
Table 150-16 ADD_TO_INCOMPATIBILITY Procedure Parameters
Parameter | Description |
---|---|
|
The name of the incompatibility definition. |
|
One or more (comma-separated) programs or jobs |
Usage Notes
This procedure does not raise an error if any specified objects already exist in the incompatibility definition.
See Also:
Using Incompatibility Definitions in Oracle Database Administrator’s Guide
150.6.5 ALTER_CHAIN Procedure
This procedure alters an attribute of the specified steps of a chain. This affects all future runs of the specified steps, both in the currently running chain job and in future runs of the same chain job or other chain jobs that point to the chain.
Syntax
Alters the value of a boolean attribute of one or more steps:
DBMS_SCHEDULER.ALTER_CHAIN ( chain_name IN VARCHAR2, step_name IN VARCHAR2, attribute IN VARCHAR2, value IN BOOLEAN);
Alters the value of a character attribute of one or more steps:
DBMS_SCHEDULER.ALTER_CHAIN ( chain_name IN VARCHAR2, step_name IN VARCHAR2, attribute IN VARCHAR2, char_value IN VARCHAR2);
Parameters
Table 150-17 ALTER_CHAIN Procedure Parameters
Parameter | Description |
---|---|
|
The name of the chain to alter |
|
The name of the step or a comma-separated list of steps to alter. This cannot be |
|
The attribute of the steps to change. Must be one of the following:
|
|
The value to set for the attribute (for a boolean attribute). |
|
The value to set for the attribute (for a character attribute). |
Usage Notes
Altering a chain requires ALTER
privileges on the chain either by being the owner of the chain, or by having the ALTER
object privilege on the chain or by having the CREATE
ANY
JOB
system privilege.
150.6.6 ALTER_RUNNING_CHAIN Procedure
This procedure alters an attribute of the specified steps of a chain. This affects only steps of the instance of the chain for the specified running chain job.
Syntax
DBMS_SCHEDULER.ALTER_RUNNING_CHAIN ( job_name IN VARCHAR2, step_name IN VARCHAR2, attribute IN VARCHAR2, value IN {BOOLEAN|VARCHAR2});
Parameters
Table 150-18 ALTER_RUNNING_CHAIN Procedure Parameters
Parameter | Description |
---|---|
|
The name of the job that is running the chain |
|
The name of the step or a comma-separated list of steps to alter. If this is set to |
attribute |
The attribute of the steps to change. Valid values are:
|
|
|
|
The value to set for the attribute. Valid values are: |
Usage Notes
Altering a running chain requires you to have alter privileges on the job that is running (either as the owner, or as a user with ALTER
privileges on the job or the CREATE
ANY
JOB
system privilege).
When trying to update a step defined with a nested chain, it is necessary to specify the job_name
as <SCHEMA>.<JOB_NAME>.<STEP_NAME_IN_TOP_LEVEL_CHAIN>
to be able to make reference to the steps inside the subchain.
150.6.7 CLOSE_WINDOW Procedure
This procedure closes an open window prematurely. A closed window means that it is no longer in effect. When a window is closed, the Scheduler switches the resource plan to the one that is in effect outside the window, or in the case of overlapping windows, to another window.
Syntax
DBMS_SCHEDULER.CLOSE_WINDOW ( window_name IN VARCHAR2);
Parameters
Table 150-19 CLOSE_WINDOW Procedure Parameters
Parameter | Description |
---|---|
|
The name of the window |
Usage Notes
If you try to close a window that does not exist or is not open, an error is generated.
A job that is running does not stop when the window it is running in closes, unless the attribute stop_on_window_close
is set to TRUE
for the job. However, the resources allocated to the job can change if the resource plan changes.
When a running job has a group of type WINDOW
as its schedule, the job is not stopped when its window is closed if another window in the same window group becomes active. This is the case even if the job has the attribute stop_on_window_close
set to TRUE
.
Closing a window requires the MANAGE
SCHEDULER
privilege.
150.6.8 COPY_JOB Procedure
This procedure copies all attributes of an existing job to a new job. The new job is created disabled, while the state of the existing job is unaltered.
Syntax
DBMS_SCHEDULER.COPY_JOB ( old_job IN VARCHAR2, new_job IN VARCHAR2);
Parameters
Table 150-20 COPY_JOB Procedure Parameters
Parameter | Description |
---|---|
|
The name of the existing job |
|
The name of the new job |
Usage Notes
To copy a job, you must have privileges to create a job in the schema of the new job (the CREATE
JOB
system privilege if it is in your own schema, otherwise, the CREATE
ANY
JOB
system privilege). If the old job is not in the your own schema, then you must also have ALTER
privileges on the old job or the CREATE
ANY
JOB
system privilege.
150.6.9 CREATE_CHAIN Procedure
This procedure creates a new chain. The chain name can be optionally qualified with a schema name (for example, myschema.myname
).
A chain is always created as disabled and must be enabled with the ENABLE Procedure before it can be used.
Syntax
DBMS_SCHEDULER.CREATE_CHAIN ( chain_name IN VARCHAR2, rule_set_name IN VARCHAR2 DEFAULT NULL, evaluation_interval IN INTERVAL DAY TO SECOND DEFAULT NULL, comments IN VARCHAR2 DEFAULT NULL);
Parameters
Table 150-21 CREATE_CHAIN Procedure Parameters
Parameter | Description |
---|---|
|
The name to assign to the new chain, which can optionally be qualified with a schema. This must be unique in the SQL namespace, therefore, there cannot already be a table or other object with this name and schema. |
|
In the normal case, no rule set should be passed in. The Scheduler automatically creates a rule set and associated empty evaluation context. You then use Advanced users can create a rule set that describes their chain dependencies and pass it in here. This allows greater flexibility in defining rules. For example, conditions can refer to external variables, and tables can be exposed through the evaluation context. If you pass in a rule set, you must ensure that it is in the format of a chain rule set. (For example, all steps must be listed as variables in the evaluation context). If no rule set is passed in, the rule set created is of the form |
|
If this is |
|
An optional comment describing the purpose of the chain |
Usage Notes
To create a chain in your own schema, you must have the CREATE
JOB
system privilege. To create a chain in a different schema you must have the CREATE
ANY
JOB
system privilege. If you do not provide a rule_set_name
, a rule set and evaluation context is created in the schema that the chain is being created in, so you must have the privileges required to create these objects. See the DBMS_RULE_ADM.CREATE_RULE_SET
and DBMS_RULE_ADM.CREATE_EVALUATION_CONTEXT
procedures for more information.
150.6.10 CREATE_CREDENTIAL Procedure
This deprecated procedure creates a stored username/password pair. Credentials are assigned to jobs so that they can authenticate with a local or remote host operating system or a remote Oracle database.
Note:
This procedure is deprecated with Oracle Database 12c Release 1 (12.1). While the procedure remains available in this package, for reasons of backward compatibility, Oracle recommends using the alternative enhanced functionality provided in the DBMS_CREDENTIAL package, specifically the CREATE_CREDENTIAL Procedure.
Syntax
DBMS_SCHEDULER.CREATE_CREDENTIAL ( credential_name IN VARCHAR2, username IN VARCHAR2, password IN VARCHAR2, database_role IN VARCHAR2 DEFAULT NULL, windows_domain IN VARCHAR2 DEFAULT NULL, comments IN VARCHAR2 DEFAULT NULL);
Parameters
Table 150-22 CREATE_CREDENTIAL Procedure Parameters
Parameter | Description |
---|---|
|
The name to assign to the credential. It can optionally be prefixed with a schema name. It cannot be set to |
|
The user name for logging into to the host operating system or remote Oracle database. This cannot be set to |
|
The password for the user name. This cannot be set to |
|
The value of the Valid values are: |
|
For a Windows remote executable target, this is the domain that the specified user belongs to. The domain is converted to uppercase automatically. Maximum length is 64. |
|
A text string that can be used to describe the credential. Scheduler does not use this parameter. Maximum length is 240. |
Usage Notes
Credentials reside in a particular schema and can be created by any user with the CREATE JOB
system privilege. To create a credential in a schema other than your own, you must have the CREATE ANY JOB
privilege.
150.6.11 CREATE_DATABASE_DESTINATION Procedure
This procedure creates a database destination. A database destination represents an Oracle database on which remote database jobs run.
The host that the remote database resides on must have a running Scheduler agent that is registered with the database that this procedure is called from.
Syntax
DBMS_SCHEDULER.CREATE_DATABASE_DESTINATION ( destination_name IN VARCHAR2, agent IN VARCHAR2, tns_name IN VARCHAR2, comments IN VARCHAR2 DEFAULT NULL);
Parameters
Table 150-23 CREATE_DATABASE_DESTINATION Procedure Parameters
Parameter | Description |
---|---|
|
The name to assign to the database destination. It can optionally be prefixed with a schema name. Cannot be |
|
The external destination name of the Scheduler agent to connect. Equivalent to an agent name. The external destination must already exist. The external destination representing an agent is created automatically on a database instance when the agent registers with that instance. An agent's name is specified in its agent configuration file. If it is not specified, it defaults to the first part (before the first period) of the name of the host it resides on. |
|
An Oracle Net connect identifier that is resolved to the Oracle database instance being connected to. The exact syntax depends on the Oracle Net configuration.The connect identifier can be a complete Oracle Net connect descriptor (network address and database service name) or a net service name, which is an alias for a connect descriptor. The alias must be resolved in the tnsnames.ora file on the local computer. The maximum size for If See Oracle Database Net Services Administrator's Guide for more information on connect identifiers. |
|
A text string that describes the database destination. Scheduler does not use this argument. |
Usage Notes
Database destinations reside in a particular schema and can be created by any user with the CREATE JOB
system privilege. To create a database destination in a schema other than your own, you must have the CREATE ANY JOB
privilege.
150.6.12 CREATE_EVENT_SCHEDULE Procedure
This procedure creates an event schedule, which is used to start a job when a particular event is raised.
Syntax
DBMS_SCHEDULER.CREATE_EVENT_SCHEDULE ( schedule_name IN VARCHAR2, start_date IN TIMESTAMP WITH TIME ZONE DEFAULT NULL, event_condition IN VARCHAR2 DEFAULT NULL, queue_spec IN VARCHAR2, end_date IN TIMESTAMP WITH TIME ZONE DEFAULT NULL, comments IN VARCHAR2 DEFAULT NULL);
Parameters
Table 150-24 CREATE_EVENT_SCHEDULE Parameters
Parameter | Description |
---|---|
|
The name to assign to the schedule. The name must be unique in the SQL namespace. For example, a schedule cannot have the same name as a table in a schema. If no name is specified, then an error occurs. |
|
This attribute specifies the date and time that this schedule becomes valid. Occurrences of the event before this date and time are ignored in the context of this schedule. |
|
This is a conditional expression based on the columns of the event source queue table. The expression must have the syntax of an Advanced Queuing rule. Accordingly, you can include user data properties in the expression, provided that the message payload is an object type, and that you prefix object attributes in the expression with |
|
This argument specifies either a file watcher name or the queue into which events that start this particular job are enqueued (the source queue). If the source queue is a secure queue, the |
|
The date and time after which jobs do not run and windows do not open. An event schedule that has no
|
|
This attribute specifies an optional comment about the schedule. By default, this attribute is |
Usage Notes
You must have the CREATE
JOB
privilege to create a schedule in your own schema or the CREATE
ANY
JOB
privilege to create a schedule in someone else's schema by specifying schema.schedule_name
. Once a schedule has been created, it can be used by other users. The schedule is created with access to PUBLIC
. Therefore, there is no need to explicitly grant access to the schedule.
See Also:
150.6.13 CREATE_FILE_WATCHER Procedure
This procedure creates a file watcher, which is a Scheduler object that defines the location, name, and other properties of a file whose arrival on a system causes the Scheduler to start a job. After you create a file watcher, you reference it in an event-based job or event schedule.
Syntax
DBMS_SCHEDULER.CREATE_FILE_WATCHER ( file_watcher_name IN VARCHAR2, directory_path IN VARCHAR2, file_name IN VARCHAR2, credential_name IN VARCHAR2, destination IN VARCHAR2 DEFAULT NULL, min_file_size IN PLS_INTEGER DEFAULT 0, steady_state_duration IN INTERVAL DAY TO SECOND DEFAULT NULL, comments IN VARCHAR2 DEFAULT NULL, enabled IN BOOLEAN DEFAULT TRUE);
Parameters
Table 150-25 CREATE_FILE_WATCHER Parameters
Parameter | Description |
---|---|
|
The name to assign to the file watcher. The name must be unique in the SQL namespace. For example, a file watcher cannot have the same name as a table in a schema. This can optionally be prefixed with a schema name. Cannot be |
|
Directory in which the file is expected to arrive. The single wildcard '?' at the beginning of the path denotes the Oracle home path. For example, '?/rdbms/log' denotes the rdbms/log subdirectory of the Oracle home directory. |
|
Name of the file to look for. Two wildcards are permitted anywhere in the file name: '?' denotes any single character, and '*' denotes zero or more characters. This attribute cannot be |
|
Name of a valid credential object. The file watcher uses the credential to authenticate itself with the host operating system to access the watched-for file. The file watcher owner must have |
|
Name of an external destination. You create an external destination by registering a remote Scheduler agent with the database. See the view |
|
Minimum size in bytes that the file must be before the file watcher considers the file found. Default is 0. |
|
Minimum time interval that the file must remain unchanged before the file watcher considers the file found. Cannot exceed one hour. If |
|
Optional comment. |
|
If |
Usage Notes
You must have the CREATE
JOB
system privilege to create a file watcher in your own schema. You require the CREATE
ANY
JOB
system privilege to create a file watcher in a schema different from your own (except the SYS
schema, which is disallowed).
150.6.14 CREATE_GROUP Procedure
This procedure creates a group. Groups contain members, which you can specify when you create the group or at a later time. There are three types of groups: window groups, database destination groups, and external destination groups.
You can use a group name in other DBMS_SCHEDULER
package procedures to specify a list of objects. For example, to specify multiple destinations for a remote database job, you provide a group name for the DESTINATION_NAME
parameter of the job.
Syntax
DBMS_SCHEDULER.CREATE_GROUP ( group_name IN VARCHAR2, group_type IN VARCHAR2, member IN VARCHAR2 DEFAULT NULL, comments IN VARCHAR2 DEFAULT NULL);
Parameters
Table 150-26 CREATE_GROUP Procedure Parameters
Parameter | Description |
---|---|
|
The name to assign to the group. It can optionally be prefixed with a schema name. It cannot be |
|
The type of members in the group. All members must be of the same type. Possible types are:
Members in database destination and external destination groups have the following format: [[schema.]credential@][schema.]destination where:
The credential portion of a destination member is optional. If omitted, the job using this destination member uses its default credential. Members in window groups are window names. Because all Scheduler windows reside in the |
|
Optional comma-separated list of group members. The default is The keyword
|
|
A text string that describes the group. Scheduler does not use this argument. |
Usage Notes
Groups reside in a particular schema and can be created by any user with the CREATE JOB
system privilege. To create a group in a schema other than your own, you must have the CREATE ANY JOB
privilege. The group name must be unique among all Scheduler objects.
You can grant the SELECT
or READ
privilege on a group so that other users can reference the group when creating jobs or schedules. To enable other users to modify a group, you can grant the ALTER
privilege on the group.
Each group member must be unique within the group. For destination groups, the credential/destination name pairs must be unique within the group. An error is generated if any of the group members do not exist. For destination groups, both the credential and destination portions of a member must exist.
Another group of the same type can be a group member. The Scheduler immediately expands the included group name into its list of members.
Groups are created enabled, but you can disable them.
Example
The following PL/SQL block creates a group named production_dest1
, whose members are database destinations for a collection of production databases.
BEGIN DBMS_SCHEDULER.CREATE_GROUP( GROUP_NAME => 'production_dest1', GROUP_TYPE => 'DB_DEST', MEMBER => 'LOCAL, oracle_cred@prodhost1, prodhost2', COMMENTS => 'All sector1 production machines'); END;
150.6.15 CREATE_INCOMPATIBILITY Procedure
This procedure creates an incompatibility definition.
Syntax
DBMS_SCHEDULER.CREATE_INCOMPATIBILITY ( incompatibility_name IN VARCHAR2, object_name IN VARCHAR2, constraint_level IN VARCHAR2 DEFAULT 'JOB_LEVEL', enabled IN BOOLEAN DEFAULT TRUE, comments IN VARCHAR2 DEFAULT NULL);
Parameters
Table 150-27 CREATE_INCOMPATIBILITY Procedure Parameters
Parameter | Description |
---|---|
|
The name of the incompatibility definition. |
|
One or more (comma-separated) programs or jobs. |
|
One or more (comma-separated) programs or jobs. |
|
Specifies whether the constraint is initially enabled ( |
|
Optional descriptive comment. |
Usage Notes
If object_name
contains multiple (comma-separated) values, they must be either all programs or all jobs that are incompatible with each other (that is, they cannot be run at the same time). For jobs, the list must consist of two or more jobs, and constraint_level
must be ‘JOB_LEVEL’. For programs, constraint_level
can be either 'JOB_LEVEL'
or 'PROGRAM_LEVEL'
. When set to the default value 'JOB_LEVEL’
, only a single job that is based on the program (or programs) mentioned in object_name
can run at the same time. When constraint_level
is set to 'PROGRAM_LEVEL'
, the programs are incompatible, but the jobs based on the same program are not incompatible.
For example, if the value of object_name
is 'P1,P2,P3'
and constraint_level
is 'PROGRAM_LEVEL’
, many jobs based on P1 can be running at the same time, but if any P1 based job is running, none based on P2 or P3 can be running. Or, similarly, many jobs based on P3 can be running at the same time, but none based on P1 or P2. If constraint_level
is set to 'JOB_LEVEL'
, then only a single job out of all the jobs based on programs P1, P2 and P3 can be running at a time.
See Also:
Using Incompatibility Definitionsin Oracle Database Administrator’s Guide
150.6.16 CREATE_JOB Procedure
This procedure creates a single job.
If you create the job as enabled by setting the enabled
attribute to TRUE
, the Scheduler automatically runs the job according to its schedule. If you create the job disabled, the job does not run until you enable it with the SET_ATTRIBUTE Procedure.
The procedure is overloaded. The different functionality of each form of syntax is presented along with the syntax declaration.
Syntax
Creates a job in a single call without using an existing program or schedule:
DBMS_SCHEDULER.CREATE_JOB ( job_name IN VARCHAR2, job_type IN VARCHAR2, job_action IN VARCHAR2, number_of_arguments IN PLS_INTEGER DEFAULT 0, start_date IN TIMESTAMP WITH TIME ZONE DEFAULT NULL, repeat_interval IN VARCHAR2 DEFAULT NULL, end_date IN TIMESTAMP WITH TIME ZONE DEFAULT NULL, job_class IN VARCHAR2 DEFAULT 'DEFAULT_JOB_CLASS', enabled IN BOOLEAN DEFAULT FALSE, auto_drop IN BOOLEAN DEFAULT TRUE, comments IN VARCHAR2 DEFAULT NULL, credential_name IN VARCHAR2 DEFAULT NULL, destination_name IN VARCHAR2 DEFAULT NULL);
Creates a job using a named schedule object and a named program object:
DBMS_SCHEDULER.CREATE_JOB ( job_name IN VARCHAR2, program_name IN VARCHAR2, schedule_name IN VARCHAR2, job_class IN VARCHAR2 DEFAULT 'DEFAULT_JOB_CLASS', enabled IN BOOLEAN DEFAULT FALSE, auto_drop IN BOOLEAN DEFAULT TRUE, comments IN VARCHAR2 DEFAULT NULL, job_style IN VARCHAR2 DEFAULT 'REGULAR', credential_name IN VARCHAR2 DEFAULT NULL, destination_name IN VARCHAR2 DEFAULT NULL);
Creates a job using a named program object and an inlined schedule:
DBMS_SCHEDULER.CREATE_JOB ( job_name IN VARCHAR2, program_name IN VARCHAR2, start_date IN TIMESTAMP WITH TIME ZONE DEFAULT NULL, repeat_interval IN VARCHAR2 DEFAULT NULL, end_date IN TIMESTAMP WITH TIME ZONE DEFAULT NULL, job_class IN VARCHAR2 DEFAULT 'DEFAULT_JOB_CLASS', enabled IN BOOLEAN DEFAULT FALSE, auto_drop IN BOOLEAN DEFAULT TRUE, comments IN VARCHAR2 DEFAULT NULL, job_style IN VARCHAR2 DEFAULT 'REGULAR', credential_name IN VARCHAR2 DEFAULT NULL, destination_name IN VARCHAR2 DEFAULT NULL);
Creates a job using a named schedule object and an inlined program:
DBMS_SCHEDULER.CREATE_JOB ( job_name IN VARCHAR2, schedule_name IN VARCHAR2, job_type IN VARCHAR2, job_action IN VARCHAR2, number_of_arguments IN PLS_INTEGER DEFAULT 0, job_class IN VARCHAR2 DEFAULT 'DEFAULT_JOB_CLASS', enabled IN BOOLEAN DEFAULT FALSE, auto_drop IN BOOLEAN DEFAULT TRUE, comments IN VARCHAR2 DEFAULT NULL, credential_name IN VARCHAR2 DEFAULT NULL, destination_name IN VARCHAR2 DEFAULT NULL);
Creates a job using an inlined program and an event:
DBMS_SCHEDULER.CREATE_JOB ( job_name IN VARCHAR2, job_type IN VARCHAR2, job_action IN VARCHAR2, number_of_arguments IN PLS_INTEGER DEFAULT 0, start_date IN TIMESTAMP WITH TIME ZONE DEFAULT NULL, event_condition IN VARCHAR2 DEFAULT NULL, queue_spec IN VARCHAR2, end_date IN TIMESTAMP WITH TIME ZONE DEFAULT NULL, job_class IN VARCHAR2 DEFAULT 'DEFAULT_JOB_CLASS', enabled IN BOOLEAN DEFAULT FALSE, auto_drop IN BOOLEAN DEFAULT TRUE, comments IN VARCHAR2 DEFAULT NULL, credential_name IN VARCHAR2 DEFAULT NULL, destination_name IN VARCHAR2 DEFAULT NULL);
Creates a job using a named program object and an event:
DBMS_SCHEDULER.CREATE_JOB ( job_name IN VARCHAR2, program_name IN VARCHAR2, start_date IN TIMESTAMP WITH TIME ZONE, event_condition IN VARCHAR2, queue_spec IN VARCHAR2, end_date IN TIMESTAMP WITH TIME ZONE, job_class IN VARCHAR2 DEFAULT 'DEFAULT_JOB_CLASS', enabled IN BOOLEAN DEFAULT FALSE, auto_drop IN BOOLEAN DEFAULT TRUE, comments IN VARCHAR2 DEFAULT NULL, job_style IN VARCHAR2 DEFAULT 'REGULAR', credential_name IN VARCHAR2 DEFAULT NULL, destination_name IN VARCHAR2 DEFAULT NULL);
Parameters
Table 150-28 CREATE_JOB Procedure Parameters
Parameter | Description |
---|---|
|
The name to assign to the job. The name must be unique in the SQL namespace. For example, a job cannot have the same name as a table in a schema. If the job being created will reside in another schema, it must be qualified with the schema name. If |
|
This attribute specifies the type of job that you are creating. If it is not specified, an error is generated. See The supported values are:
|
|
This attribute specifies the action of the job. If The job action is executed inside an autonomous transaction, and all autonomous transaction guidelines and restrictions apply. For example, online DDL operations are not allowed inside an autonomous transaction, and therefore cannot be used in the job action. The following actions are possible:
|
|
This attribute specifies the number of arguments that the job expects. The range is 0-255, with the default being 0. |
|
The name of the program associated with this job. If the program is of type |
|
This attribute specifies the first date and time on which this job is scheduled to start. If For repeating jobs that use a calendaring expression to specify the repeat interval, The Scheduler cannot guarantee that a job executes on an exact time because the system may be overloaded and thus resources unavailable. |
|
This is a conditional expression based on the columns of the event source queue table. The expression must have the syntax of an Advanced Queuing rule. Accordingly, you can include user data properties in the expression provided that the message payload is an object type, and that you prefix object attributes in the expression with |
|
This argument specifies either of the following:
|
|
This attribute specifies how often the job repeats. You can specify the repeat interval by using calendaring or PL/SQL expressions. The expression specified is evaluated to determine the next time the job should run. If |
|
The name of the schedule, window, or window group associated with this job. |
|
The class this job is associated with. |
|
This attribute specifies the date and time after which the job expires and is no longer run. After the If no value for The value for |
|
This attribute specifies a comment about the job. By default, this attribute is |
|
Style of the job being created. This argument can have one of the following values:
|
|
The default credential to use with the job. Applicable only to remote database jobs, remote external jobs, local external jobs, script jobs, and event-based jobs that process file arrival events. The credential must exist. For local database jobs, it must be For local external jobs only, if this attribute is See also: "CREATE_CREDENTIAL Procedure" |
|
The database destination or external destination for the job. Use for remote database jobs and remote external jobs only. Must be This attribute can be a single destination name or the name of a group of type ' The following applies to this attribute:
If the
The credential must already exist. If the You can query the views *** |
|
This attribute specifies whether the job is created enabled or not. The possible settings are |
|
This flag, if
A job is disabled when it has failed If this flag is set to By default, jobs are created with |
Usage Notes
Jobs are created as disabled by default. You must explicitly enable them so that they will become active and scheduled. Before enabling a job, ensure that all program arguments, if any, are defined, either by defining default values in the program object or by supplying values with the job.
The JOB_QUEUE_PROCESSES
initialization parameter specifies the maximum number of processes that can be created for the execution of jobs. Beginning with Oracle Database 11g Release 2, JOB_QUEUE_PROCESSES
applies to DBMS_SCHEDULER
jobs. Setting this parameter to 0 disables DBMS_SCHEDULER
jobs.
To create a job in your own schema, you need to have the CREATE
JOB
privilege. A user with the CREATE
ANY
JOB
privilege can create a job in any schema. If the job being created will reside in another schema, the job name must be qualified with the schema name. For a job of type EXECUTABLE
(or for a job that points to a program of type EXECUTABLE
), the job owner must have the CREATE EXTERNAL JOB
system privilege before the job can be enabled or run.
Associating a job with a particular class or program requires EXECUTE
privileges for that class or program.
Not all possible job attributes can be set with CREATE_JOB
. Some must be set after the job is created. For example, job arguments must be set with the SET_JOB_ARGUMENT_VALUE Procedure or the SET_JOB_ANYDATA_VALUE Procedure. Other job attributes, such as job_priority
and max_runs
, are set with the SET_ATTRIBUTE Procedure.
To create multiple jobs efficiently, use the CREATE_JOBS
procedure.
Note:
The Scheduler runs event-based jobs for each occurrence of an event that matches the event condition of the job. However, events that occur while the job is already running are ignored; the event gets consumed, but does not trigger another run of the job.
150.6.17 CREATE_JOB_CLASS Procedure
This procedure creates a job class. Job classes are created in the SYS
schema.
Syntax
DBMS_SCHEDULER.CREATE_JOB_CLASS ( job_class_name IN VARCHAR2, resource_consumer_group IN VARCHAR2 DEFAULT NULL, service IN VARCHAR2 DEFAULT NULL, logging_level IN PLS_INTEGER DEFAULT DBMS_SCHEDULER.LOGGING_RUNS, log_history IN PLS_INTEGER DEFAULT NULL, comments IN VARCHAR2 DEFAULT NULL);
Parameters
Table 150-29 CREATE_JOB_CLASS Procedure Parameters
Parameter | Description |
---|---|
|
The name to assign to the job class. Job classes can only be created in the This attribute specifies the name of the job class and uniquely identifies the job class. The name must be unique in the SQL namespace. For example, a job class cannot have the same name as a table in a schema. |
|
This attribute specifies the resource consumer group that his class is associated with. A resource consumer group is a set of synchronous or asynchronous sessions that are grouped together based on their processing needs. A job class has a many-to-one relationship with a resource consumer group. The resource consumer group that the job class associates with determines the resources that are allocated to the job class. If a resource consumer group is dropped, job classes associated with it are then associated with the default resource consumer group. If no resource consumer group is specified, job classes are associated with the default resource consumer group. If the specified resource consumer group does not exist when creating the job class, an error occurs. |
|
This attribute specifies the database service that the jobs in this class have affinity to. In an Oracle RAC environment, this means that the jobs in this class only run on those database instances that are assigned to the specific service. Note that a service can be mapped to a resource consumer group, so you can also control resources allocated to jobs by specifying a service. See If no service is specified, the job class belongs to the default service, which means it has no service affinity and any one of the database instances within the cluster might run the job. If the service that a job class belongs to is dropped, the job class will then belong to the default service. If the specified service does not exist when creating the job class, then an error occurs. |
|
This attribute specifies how much information is logged. The possible options are:
|
|
This attribute controls the number of days that job log entries for jobs in this class are retained. It helps prevent the job log from growing indiscriminately. The range of valid values is 0 through1000000. If set to 0, no history is kept. If |
|
This attribute is for an optional comment about the job class. By default, this attribute is |
Usage Notes
For users to create jobs that belong to a job class, the job owner must have EXECUTE
privileges on the job class. Therefore, after the job class has been created, EXECUTE
privileges must be granted on the job class so that users create jobs belonging to that class. You can also grant the EXECUTE
privilege to a role.
Creating a job class requires the MANAGE
SCHEDULER
system privilege.
150.6.18 CREATE_JOBS Procedure
This procedure creates multiple jobs and sets the values of their arguments in a single call.
Syntax
DBMS_SCHEDULER.CREATE_JOBS ( jobdef_array IN SYS.JOB_DEFINITION_ARRAY, commit_semantics IN VARCHAR2 DEFAULT 'STOP_ON_FIRST_ERROR');
Parameters
Table 150-30 CREATE_JOBS Procedure Parameters
Parameter | Description |
---|---|
|
The array of job definitions. See "Data Structures" for a description of the |
|
The commit semantics. The following types are supported:
|
Usage Notes
This procedure creates many jobs in the context of a single transaction. To realize the desired performance gains, the jobs being created must be grouped in batches of sufficient size. Calling CREATE_JOBS
with a small array size may not be much faster than calling CREATE_JOB
once for each job.
You cannot use this procedure to create multiple-destination jobs. That is, the destination
attribute of the job_definition
object cannot reference a destination group.
Examples
150.6.19 CREATE_PROGRAM Procedure
This procedure creates a program.
Syntax
DBMS_SCHEDULER.CREATE_PROGRAM ( program_name IN VARCHAR2, program_type IN VARCHAR2, program_action IN VARCHAR2, number_of_arguments IN PLS_INTEGER DEFAULT 0, enabled IN BOOLEAN DEFAULT FALSE, comments IN VARCHAR2 DEFAULT NULL);
Parameters
Table 150-31 CREATE_PROGRAM Procedure Parameters
Parameter | Description |
---|---|
|
The name to assign to the program. The name must be unique in the SQL namespace. For example, a program cannot have the same name as a table in a schema. If no name is specified, then an error occurs. |
|
This attribute specifies the type of program you are creating. If it is not specified then you get an error. These are the supported values for
|
|
This attribute specifies the action of the program. If project 25230 last 3 bullets The following actions are possible:
|
|
This attribute specifies the number of arguments the program takes. If this parameter is not specified, then the default is 0. A program can have a maximum of 255 arguments. If the |
|
This flag specifies whether the program should be created as enabled or not. If the flag is set to |
|
A comment about the program. By default, this attribute is |
Usage Notes
To create a program in their own schema, users need the CREATE
JOB
privilege. A user with the CREATE
ANY
JOB
privilege can create a program in any schema. A program is created in a disabled state by default (unless the enabled parameter is set to TRUE
). It cannot be executed by a job until it is enabled.
To use your programs, other users must have EXECUTE
privileges, therefore once a program has been created, you have to grant EXECUTE
privileges on it.
See Also:
150.6.20 CREATE_RESOURCE Procedure
This procedure allows users to specify the resources used by jobs or to create a new resource.
Syntax
DBMS_SCHEDULER.CREATE_RESOURCE ( resource_name IN VARCHAR2, units IN PLS_INTEGER, status IN VARCHAR2 DEFAULT 'ENFORCE_CONSTRAINTS', constraint_level IN VARCHAR2 DEFAULT 'JOB_LEVEL', comments IN VARCHAR2 DEFAULT NULL);
Parameters
Table 150-32 CREATE_RESOURCE Procedure Parameters
Parameter | Description |
---|---|
|
The name of the resource. |
|
The number of units of this resource that the job or program uses. |
|
The status of the resource.
|
|
Level of the constraint: For incompatibilities, for |
|
Descriptive comment about the resource. |
Usage Notes
The following example creates a new resource.
BEGIN DBMS_SCHEDULER.CREATE_RESOURCE( resource_name => 'my_resource', units => 3, state => 'ENFORCE_CONSTRAINTS', comments => 'Resource1' ) END; /
See Also:
-
Creating or Dropping a Resource in Oracle Database Administrator’s Guide
150.6.21 CREATE_SCHEDULE Procedure
This procedure creates a schedule.
Syntax
DBMS_SCHEDULER.CREATE_SCHEDULE ( schedule_name IN VARCHAR2, start_date IN TIMESTAMP WITH TIMEZONE DEFAULT NULL, repeat_interval IN VARCHAR2, end_date IN TIMESTAMP WITH TIMEZONE DEFAULT NULL, comments IN VARCHAR2 DEFAULT NULL);
Parameters
Table 150-33 CREATE_SCHEDULE Procedure Parameters
Parameter | Description |
---|---|
|
The name to assign to the schedule. The name must be unique in the SQL namespace. For example, a schedule cannot have the same name as a table in a schema. If no name is specified, then an error occurs. |
|
This attribute specifies the first date and time on which this schedule becomes valid. For a repeating schedule, the value for If If |
|
This attribute specifies how often the schedule repeats. It is expressed using calendaring syntax. See "Calendaring Syntax" for further information. PL/SQL expressions are not allowed as repeat intervals for named schedules. |
|
The date and time after which jobs will not run and windows will not open. A non-repeating schedule that has no
|
|
This attribute specifies an optional comment about the schedule. By default, this attribute is |
Usage Notes
This procedure requires the CREATE
JOB
privilege to create a schedule in your own schema or the CREATE
ANY
JOB
privilege to create a schedule in someone else's schema by specifying schema.schedule_name
. Once a schedule has been created, it can be used by other users. The schedule is created with access to PUBLIC
. Therefore, there is no need to explicitly grant access to the schedule.
150.6.22 CREATE_WINDOW Procedure
This procedure creates a recurring time window and associates it with a resource plan. You can then use the window to schedule jobs that run under the associated resource plan. Windows are created in the SYS
schema.
The procedure is overloaded.
Syntax
Creates a window using a named schedule object:
DBMS_SCHEDULER.CREATE_WINDOW ( window_name IN VARCHAR2, resource_plan IN VARCHAR2, schedule_name IN VARCHAR2, duration IN INTERVAL DAY TO SECOND, window_priority IN VARCHAR2 DEFAULT 'LOW', comments IN VARCHAR2 DEFAULT NULL);
Creates a window using an inlined schedule:
DBMS_SCHEDULER.CREATE_WINDOW ( window_name IN VARCHAR2, resource_plan IN VARCHAR2, start_date IN TIMESTAMP WITH TIME ZONE DEFAULT NULL, repeat_interval IN VARCHAR2, end_date IN TIMESTAMP WITH TIME ZONE DEFAULT NULL, duration IN INTERVAL DAY TO SECOND, window_priority IN VARCHAR2 DEFAULT 'LOW', comments IN VARCHAR2 DEFAULT NULL);
Parameters
Table 150-34 CREATE_WINDOW Procedure Parameters
Parameter | Description |
---|---|
|
The name to assign to the window. The name must be unique in the SQL namespace. All windows are in the |
|
This attribute specifies the resource plan that automatically activates when the window opens. When the window closes, the system switches to the appropriate resource plan, which is usually the plan that was in effect before the window opened, but can also be the plan of a different window. Only one resource plan can be associated with a window. It may be If the window is open and the resource plan is dropped, then the resource allocation for the duration of the window is not affected. |
|
This attribute specifies the first date and time on which this window is scheduled to open. If the value for For repeating windows that use a calendaring expression to specify the repeat interval, the value for |
|
This attribute specifies how long the window stays open. For example, |
|
This attribute specifies the name of the schedule associated with the window. |
|
This attribute specifies how often the window repeats. It is expressed using the Scheduler calendaring syntax. See "Calendaring Syntax" for more information. A PL/SQL expression cannot be used to specify the repeat interval for a window. The expression specified is evaluated to determine the next time the window opens. If no |
|
This attribute specifies the date and time after which the window no longer opens. When the value for A non-repeating window that has no value for The |
|
This attribute is only relevant when two windows overlap. Because only one window can be in effect at one time, the window priority determines which window opens. The two possible values for this attribute are ' |
|
This attribute specifies an optional comment about the window. By default, this attribute is |
Usage Notes
Creating a window requires the MANAGE
SCHEDULER
privilege.
Scheduler windows are the principal mechanism used to automatically switch resource plans according to a schedule. You can also manually activate a resource plan by using the ALTER SYSTEM SET RESOURCE_MANAGER_PLAN
statement or the DBMS_RESOURCE_MANAGER.SWITCH_PLAN
package procedure. Note that either of these manual methods can also disable resource plan switching by Scheduler windows. For more information, see Oracle Database Administrator's Guide and "SWITCH_PLAN Procedure".
150.6.23 DEFINE_ANYDATA_ARGUMENT Procedure
This procedure defines a name or default value for a program argument that is of a complex type and must be encapsulated within an ANYDATA
object. A job that references the program can override the default value.
Syntax
DBMS_SCHEDULER.DEFINE_ANYDATA_ARGUMENT ( program_name IN VARCHAR2, argument_position IN PLS_INTEGER, argument_name IN VARCHAR2 DEFAULT NULL, argument_type IN VARCHAR2, default_value IN SYS.ANYDATA, out_argument IN BOOLEAN DEFAULT FALSE);
Parameters
Table 150-35 DEFINE_ANYDATA_ARGUMENT Procedure Parameters
Parameter | Description |
---|---|
|
The name of the program to be altered. A program with this name must exist. |
|
The position of the argument as it is passed to the executable. Argument numbers go from one to the |
|
The name to assign to the argument. It is optional, but must be unique for the program if it is specified. If you assign a name, the name can then be used by other package procedures, including the SET_JOB_ANYDATA_VALUE Procedure. |
|
The datatype of the argument being defined. This is not verified or used by the Scheduler. It is only used by the user of the program when deciding what value to assign to the argument. |
|
The default value to be assigned to the argument encapsulated within an |
|
This parameter is reserved for future use. It must be set to |
Usage Notes
All program arguments from one to the number_of_arguments
value must be defined before a program can be enabled. If a default value for an argument is not defined with this procedure, a value must be defined in the job.
Defining a program argument requires that you be the owner of the program or have ALTER
privileges on that program. You can also define a program argument if you have the CREATE
ANY
JOB
privilege.
150.6.24 DEFINE_CHAIN_EVENT_STEP Procedure
This procedure adds or replaces a chain step and associates it with an event schedule or an inline event.
Once started in a running chain, this step does not complete until the specified event has occurred. Every step in a chain must be defined before the chain can be enabled and used. Defining a step gives it a name and specifies what happens during the step. If a step already exists with this name, the new step replaces the old one.
Syntax
DBMS_SCHEDULER.DEFINE_CHAIN_EVENT_STEP ( chain_name IN VARCHAR2, step_name IN VARCHAR2, event_schedule_name IN VARCHAR2, timeout IN INTERVAL DAY TO SECOND DEFAULT NULL); DBMS_SCHEDULER.DEFINE_CHAIN_EVENT_STEP ( chain_name IN VARCHAR2, step_name IN VARCHAR2, event_condition IN VARCHAR2, queue_spec IN VARCHAR2, timeout IN INTERVAL DAY TO SECOND DEFAULT NULL);
Parameters
Table 150-36 DEFINE_CHAIN_EVENT_STEP Procedure Parameters
Parameter | Description |
---|---|
|
The name of the chain that the step is in |
|
The name of the step |
|
The name of the event schedule that the step waits for |
|
This parameter is reserved for future use |
|
See the CREATE_EVENT_SCHEDULE Procedure |
|
See the CREATE_EVENT_SCHEDULE Procedure |
Usage Notes
Defining a chain step requires ALTER
privileges on the chain either as the owner of the chain, or as a user with the ALTER
object privilege on the chain or the CREATE
ANY
JOB
system privilege.
You can base a chain step on a file watcher as well. To do this, provide the file watcher name directly in the queue_spec
parameter, or use a file watcher schedule for the event_schedule_name
parameter.
See Also:
150.6.25 DEFINE_CHAIN_RULE Procedure
This procedure adds a new rule to an existing chain, specified as a condition-action pair. The condition is expressed using either SQL or the Scheduler chain condition syntax and indicates the prerequisites for the action to occur. The action is a result of the condition being met.
An actual rule object is created to store the rule in the schema where the chain resides. If a rule name is given, this name is used for the rule object. If an existing rule name in the schema of the chain is given, the existing rule is altered. (A schema different than the schema of the chain cannot be specified). If no rule name is given, one is generated in the form SCHED_RULE${N}
.
Syntax
DBMS_SCHEDULER.DEFINE_CHAIN_RULE ( chain_name IN VARCHAR2, condition IN VARCHAR2, action IN VARCHAR2, rule_name IN VARCHAR2 DEFAULT NULL, comments IN VARCHAR2 DEFAULT NULL);
Parameters
Table 150-37 DEFINE_CHAIN_RULE Procedure Parameters
Parameter | Description |
---|---|
|
The name of the chain to alter |
|
A boolean expression which must evaluate to
|
|
The action to be performed when the rule evaluates to Possible actions include:
At the beginning of the The |
|
The name of the rule being created. If no |
|
An optional comment describing the rule. This is stored in the rule object created. |
Scheduler Chain Condition Syntax
The Scheduler chain condition syntax provides an easy way to construct a condition using the states and error codes of steps in the current chain.
Chain Condition Syntax
The following are the available constructs for Scheduler chain condition syntax, which are all boolean expressions:
TRUE FALSE stepname [NOT] SUCCEEDED stepname [NOT] FAILED stepname [NOT] STOPPED stepname [NOT] COMPLETED stepname ERROR_CODE IN (integer, integer, integer ...) stepname ERROR_CODE NOT IN (integer, integer, integer ...) stepname ERROR_CODE = integer stepname ERROR_CODE != integer stepname ERROR_CODE <> integer stepname ERROR_CODE > integer stepname ERROR_CODE >= integer stepname ERROR_CODE < integer stepname ERROR_CODE <= integer
These boolean operators are available to create more complex conditions:
expression AND expression expression OR expression NOT (expression)
integer
can be positive or negative. Parentheses may be used for clarity or to enforce ordering. You must use parentheses with the NOT
operator.
PL/SQL code that runs as part of a step can set the value of ERROR_CODE
for that step with the RAISE_APPLICATION_ERROR
statement.
Usage Notes
Defining a chain rule requires ALTER
privileges on the chain (either as the owner, or as a user with ALTER
privileges on the chain or the CREATE
ANY
JOB
system privilege).
You must define at least one rule that starts the chain and at least one that ends it. See the section "Adding Rules to a Chain" in Oracle Database Administrator's Guide for more information.
Examples
The following are examples of using rule conditions and rule actions.
Rule Conditions Using Scheduler Chain Condition Syntax
'step1 completed' -- satisfied when step step1 has completed. (step1 completed is also TRUE when any -- of the following are TRUE: step1 succeeded, step1 failed, step1 stopped.) 'step1 succeeded and step2 succeeded' -- satisfied when steps step1 and step2 have both succeeded 'step1 error_code > 100' -- satisfied when step step1 has failed with an error_code greater than 100 'step1 error_code IN (1, 3, 5, 7)' -- satisfied when step step1 has failed with an error_code of 1, 3, 5, or 7
Rule Conditions Using SQL Syntax
':step1.completed = ''TRUE'' AND :step1.end_date >SYSDATE-1/24' --satisfied when step step1 completed less than an hour ago ':step1.duration > interval ''5'' minute' -- satisfied when step step1 has completed and took longer than 5 minutes to complete
Rule Actions
'AFTER 01:00:00 START step1, step2' --After an hour start steps step1 and step2 'STOP step1' --Stop step step1 END step4.error_code' --End the chain with the error code that step step4 finished with. If step4 has not completed, the chain will be ended unsuccessfully with error code 27435. 'END' or 'END 0' --End the chain successfully (with error_code 0) 'END 100' --End the chain unsuccessfully with error code 100.
150.6.26 DEFINE_CHAIN_STEP Procedure
This procedure adds or replaces a chain step and associates it with a program or a nested chain. When the chain step is started, the specified program or chain is run. If a step already exists with the name supplied in the chain_name
argument, the new step replaces the old one.
The chain owner must have EXECUTE
privileges on the program or chain associated with the step. Only one program or chain can run during a step.
You cannot set all possible step attributes with this procedure. Use the ALTER_CHAIN
procedure to set additional chain step attributes, such as credential_name
and destination_name
.
Syntax
DBMS_SCHEDULER.DEFINE_CHAIN_STEP ( chain_name IN VARCHAR2, step_name IN VARCHAR2, program_name IN VARCHAR2);
Parameters
Table 150-38 DEFINE_CHAIN_STEP Procedure Parameters
Parameter | Description |
---|---|
|
The name of the chain to alter. |
|
The name of the step being defined. If a step already exists with this name, the new step replaces the old one. |
|
The name of a program or chain to run during this step. The chain owner must have |
Usage Notes
Defining a chain step requires ALTER
privileges on the chain (either as the owner, or a user with ALTER
privileges on the chain or the CREATE
ANY
JOB
system privilege).
See Also:
150.6.27 DEFINE_METADATA_ARGUMENT Procedure
This procedure defines a special metadata argument for the program. The Scheduler can pass Scheduler metadata through this argument to your stored procedure or other executable. You cannot set values for jobs using this argument.
Syntax
DBMS_SCHEDULER.DEFINE_METADATA_ARGUMENT ( program_name IN VARCHAR2, metadata_attribute IN VARCHAR2, argument_position IN PLS_INTEGER, argument_name IN VARCHAR2 DEFAULT NULL);
Parameters
Table 150-39 DEFINE_METADATA_ARGUMENT Procedure Parameters
Parameter | Description |
---|---|
|
The name of the program to be altered |
|
The metadata to be passed. Valid metadata attributes are: ' Table 150-40 describes these attributes in detail. |
|
The position of the argument as it is passed to the executable. The position cannot be greater than the |
|
The name to assign to the argument. It is optional, but must be unique for the program if it is specified. If you assign a name, the name can then be used by other package procedures. |
Table 150-40 Metadata Attributes
Metadata Attribute | Datatype | Description |
---|---|---|
|
|
Name of the currently running job |
|
|
Subname of the currently running job. The name + subname form a unique identifier for a job that is running a chain step. |
|
|
Owner of the currently running job |
|
|
When the currently running job was scheduled to start |
|
|
When the currently running job started |
|
|
If the job was started by a window, the time that the window opened |
|
|
If the job was started by a window, the time that the window is scheduled to close |
|
(See Description) |
For an event-based job, the message content of the event that started the job. The datatype of this attribute depends on the queue used for the event. It has the same type as the |
Usage Notes
Defining a program argument requires that you be the owner of the program or have ALTER
privileges on that program. You can also define a program argument if you have the CREATE
ANY
JOB
privilege.
All metadata attributes except event_message
can be used in PL/SQL blocks that you enter into the job_action
or program_action
attributes of jobs or programs, respectively. You use the attribute name as you use any other PL/SQL identifier, and the Scheduler assigns it a value.
150.6.28 DEFINE_PROGRAM_ARGUMENT Procedure
This procedure defines a name or default value for a program argument. If no default value is defined for a program argument, the job that references the program must supply an argument value. (The job can also override a default value.)
This procedure is overloaded.
Syntax
Defines a program argument without a default value:
PROCEDURE define_program_argument( program_name IN VARCHAR2, argument_position IN PLS_INTEGER, argument_name IN VARCHAR2 DEFAULT NULL, argument_type IN VARCHAR2, out_argument IN BOOLEAN DEFAULT FALSE);
Defines a program argument with a default value:
PROCEDURE define_program_argument( program_name IN VARCHAR2, argument_position IN PLS_INTEGER, argument_name IN VARCHAR2 DEFAULT NULL, argument_type IN VARCHAR2, default_value IN VARCHAR2, out_argument IN BOOLEAN DEFAULT FALSE);
Parameters
Table 150-41 DEFINE_PROGRAM_ARGUMENT Procedure Parameters
Parameter | Description |
---|---|
|
The name of the program to be altered. A program with this name must exist. |
|
The position of the argument as it is passed to the executable. Argument numbers go from one to the |
|
The name to assign to the argument. It is optional, but must be unique for the program if specified. If you assign a name, the name can then be used by other package procedures, including the SET_JOB_ARGUMENT_VALUE Procedure. |
|
The datatype of the argument being defined. This is not verified or used by the Scheduler. The program user uses argument_type when deciding what value to assign to the argument. Any valid SQL datatype is allowed. |
|
The default value to be assigned to the argument if none is specified by the job. |
|
This parameter is reserved for future use. It must be set to |
Usage Notes
All program arguments from 1 to the number_of_arguments
value must be defined before a program can be enabled. If a default value for an argument is not defined with this procedure, a value must be defined in the job.
Defining a program argument requires that you be the owner of the program or have ALTER
privileges on that program. You can also define a program argument if you have the CREATE
ANY
JOB
privilege.
DEFINE_PROGRAM_ARGUMENT
only supports arguments of SQL type. Therefore, argument values that are not of SQL type, such as booleans, are not supported as program or job arguments.
150.6.29 DISABLE Procedure
This procedure disables a program, job, chain, window, database destination, external destination, file watcher, or group. When an object is disabled, its enabled
attribute is set to FALSE
.
Syntax
DBMS_SCHEDULER.DISABLE ( name IN VARCHAR2, force IN BOOLEAN DEFAULT FALSE, commit_semantics IN VARCHAR2 DEFAULT 'STOP_ON_FIRST_ERROR');
Parameters
Table 150-42 DISABLE Procedure Parameters
Parameter | Description |
---|---|
|
The name of the object being disabled. Can be a comma-delimited list. If a job class name is specified, then all the jobs in the job class are disabled. The job class is not disabled. If a group name is specified, then the group is disabled, but the enabled state of the group members is unaffected. |
|
If |
|
The commit semantics. The following types are supported:
|
Usage Notes
Windows must be preceded by SYS
.
Disabling an object that is already disabled does not generate an error.
The purpose of the force
option is to point out dependencies. No dependent objects are altered.
To run DISABLE
for a window or a group of type WINDOW
, you must have the MANAGE
SCHEDULER
privilege.
You can use DISABLE
with any schema except the SYS
schema.
Jobs
Disabling a job means that, although the metadata of the job is there, it should not run and the job coordinator will not pick up these jobs for processing. When a job is disabled, its state
in the job queue is changed to disabled
.
If force
is set to FALSE
and the job is currently running, an error is returned.
If force
is set to TRUE
, the job is disabled, but the currently running instance is allowed to finish.
For jobs with multiple destinations, you cannot disable a child job at a specific destination. Instead, you can disable the destination.
Programs
When a program is disabled, the status is changed to disabled. A disabled program implies that, although the metadata is still there, jobs that point to this program cannot run.
If force
is set to FALSE
, the program must not be referenced by any job, otherwise an error will occur.
If force
is set to TRUE
, those jobs that point to the program will not be disabled, however, they will fail at runtime because their program will not be valid.
Running jobs that point to the program are not affected by the DISABLE
call and are allowed to continue
No arguments that pertain to the program are affected when the program is disabled.
File Watchers
If force
is set to FALSE
, the file watcher must not be referenced by any job, otherwise an error will occur. If you force disabling a file watcher, jobs that depend on it become disabled.
Windows
This means that the window will not open, however, the metadata of the window is still there, so it can be reenabled.
If force
is set to FALSE
, the window must not be open or referenced by any job otherwise an error occurs.
If force
is set to TRUE
, disabling a window that is open will succeed but the window will not be closed. It will prevent the window from opening in the future until it is reenabled.
When the window is disabled, those jobs that have the window as their schedule will not be disabled.
Window Groups
When a group of type WINDOW
is disabled, jobs (other than a running job) that have the window group as their schedule will not run when the member windows open. However, a job that has one of the window group members as its schedule still runs.
The metadata of the window group is still there, so it can be reenabled. Note that the members of the window group will still open.
If force
is set to FALSE
, the window group must not have any members that are open or referenced by any job, otherwise an error will occur.
If force
is set to TRUE
:
-
The window group is disabled and the open window will be not closed or disabled. It will be allowed to continue to its end.
-
The window group is disabled but those jobs that have the window group as their schedule will not be disabled.
Job Chains
When a chain is disabled, the metadata for the chain is still there, but jobs that point to it will not be able to be run. This allows changes to the chain to be made safely without the risk of having an incompletely specified chain run.If force
is set to FALSE
, the chain must not be referenced by any job, otherwise an error will occur.If force
is set to TRUE
, those jobs that point to the chain will not be disabled, however, they will fail at runtime.Running jobs that point to this chain are not affected by the DISABLE
call and are allowed to complete.
Database Destinations
When you disable a database destination:
-
The destination is skipped when a multiple destination job runs.
-
If all destinations are disabled for a job, the Scheduler generates an error when it attempts to run the job.
-
The
REFS_ENABLED
column in*_SCHEDULER_JOB_DESTS
is set toFALSE
for all jobs that reference the database destination.
External Destinations
When you disable an external destination:
-
Dependent database destinations remain enabled, but the Scheduler generates an error when it attempts to run a job with a database destination that depends on the external destination.
-
The
REFS_ENABLED
column in*_SCHEDULER_JOB_DESTS
is set toFALSE
for all external jobs that reference the external destination and for all database jobs with a database destination that depends on the external destination.
Groups
If you disable an external destination group or database destination group, the Scheduler generates an error when it attempts to run a job that names the group as its destination.
150.6.30 DROP_AGENT_DESTINATION Procedure
This procedure drops one or more external destinations, also known as agent destinations. It should be used only when the preferred method of dropping an external destination, using the schagent
utility to unregister a Scheduler agent with a database, is unavailable due to failures.
This procedure can be called only by the SYS
user or a user with the MANAGE
SCHEDULER
privilege.
Note:
External destinations are created on a source database only implicitly by registering an agent with the database. There is no user-callable CREATE_AGENT_DESTINATION
procedure.
Syntax
DBMS_SCHEDULER.DROP_AGENT_DESTINATION ( destination_name IN VARCHAR2);
Parameters
Table 150-43 DROP_AGENT_DESTINATION Procedure Parameters
Parameter | Description |
---|---|
|
A comma-separated list of external destinations to drop. Because user The procedure stops processing if it encounters an external destination that does not exist. All external destinations processed before the error are dropped. Cannot be |
Usage Notes
When an external destination is dropped:
-
All database destinations that refer to the external destination are disabled and their
agent
attribute is set toNULL
. -
Members of external destination groups that refer to the destination are removed from the group.
-
All job instances in the
*_SCHEDULER_JOB_DESTS
views that refer to the external destination are also dropped. -
Jobs running against the destination are stopped.
150.6.31 DROP_CHAIN Procedure
This procedure drops an existing chain.
Syntax
DBMS_SCHEDULER.DROP_CHAIN ( chain_name IN VARCHAR2, force IN BOOLEAN DEFAULT FALSE);
Parameters
Table 150-44 DROP_CHAIN Procedure Parameters
Parameter | Description |
---|---|
|
The name of the chain to drop. Can also be a comma-delimited list of chains. |
|
If If |
Usage Notes
Dropping a chain requires alter privileges on the chain (either as the owner, or a user with ALTER
privileges on the chain or the CREATE
ANY
JOB
system privilege).
All steps associated with the chain are dropped. If no rule set was specified when the chain was created, then the automatically created rule set and evaluation context associated with the chain are also dropped, so the user must have the privileges required to do this. See the DBMS_RULE_ADM.DROP_RULE_SET
and DBMS_RULE_ADM.DROP_EVALUATION_CONTEXT
procedures for more information.
If force
is FALSE
, no jobs may be using this chain. If force
is TRUE
, any jobs that use this chain are disabled before the chain is dropped (and any of these jobs that are running will be stopped).
150.6.32 DROP_CHAIN_RULE Procedure
This procedure removes a rule from an existing chain. The rule object corresponding to this rule will also be dropped. The chain will not be disabled. If dropping this rule makes the chain invalid, the user should first disable the chain to ensure that it does not run.
Syntax
DBMS_SCHEDULER.DROP_CHAIN_RULE ( chain_name IN VARCHAR2, rule_name IN VARCHAR2, force IN BOOLEAN DEFAULT FALSE);
Parameters
Table 150-45 DROP_CHAIN_RULE Procedure Parameters
Parameter | Description |
---|---|
|
The name of the chain to alter |
|
The name of the rule to drop |
|
If |
Usage Notes
Dropping a chain rule requires alter privileges on the chain (either as the owner or as a user with ALTER
privileges on the chain or the CREATE
ANY
JOB
system privilege).
Dropping a chain rule also drops the underlying rule database object so you must have the privileges to drop this rule object. See the DBMS_RULE_ADM.DROP_RULE
procedure for more information.
150.6.33 DROP_CHAIN_STEP Procedure
This procedure drops a chain step. If this chain step is still used in the chain rules, the chain will be disabled.
Syntax
DBMS_SCHEDULER.DROP_CHAIN_STEP ( chain_name IN VARCHAR2, step_name IN VARCHAR2, force IN BOOLEAN DEFAULT FALSE);
Parameters
Table 150-46 DROP_CHAIN_STEP Procedure Parameters
Parameter | Description |
---|---|
|
The name of the chain to alter |
|
The name of the step being dropped. Can be a comma-separated list. |
|
If |
Usage Notes
Dropping a chain step requires ALTER
privileges on the chain (either as the owner or as a user with ALTER
privileges on the chain or the CREATE
ANY
JOB
system privilege).
150.6.34 DROP_CREDENTIAL Procedure
This deprecated procedure drops a credential.
Note:
This procedure is deprecated with Oracle Database 12c Release 1 (12.1). While the procedure remains available in this package, for reasons of backward compatibility, Oracle recommends using the alternative enhanced functionality provided in the DBMS_CREDENTIAL package, specifically the DROP_CREDENTIAL Procedure.
Syntax
DBMS_SCHEDULER.DROP_CREDENTIAL ( credential_name IN VARCHAR2, force IN BOOLEAN DEFAULT FALSE);
Parameters
Table 150-47 DROP_CREDENTIAL Procedure Parameters
Parameter | Description |
---|---|
|
The name of the credential being dropped. This can optionally be prefixed with a schema name. This cannot be set to |
|
If set to |
Usage Notes
Only the owner of a credential or a user with the CREATE ANY JOB
system privilege may drop the credential.
Running jobs that point to the credential are not affected by this procedure and are allowed to continue.
150.6.35 DROP_DATABASE_DESTINATION Procedure
This procedure drops one or more database destinations.
Syntax
DBMS_SCHEDULER.DROP_DATABASE_DESTINATION ( destination_name IN VARCHAR2);
Parameters
Table 150-48 DROP_DATABASE_DESTINATION Procedure Parameters
Parameter | Description |
---|---|
|
The name of the destination to drop. Can be a comma-separated list of database destinations to drop. Each database destination can optionally be prefixed with a schema name. The procedure stops processing if it encounters a database destination that does not exist. All database destinations processed before the error are dropped. Cannot be |
Usage Notes
Only the owner or a user with the CREATE ANY JOB
system privilege may drop the database destination.
When a database destination is dropped:
-
All job instances that refer to the destination in the
*_SCHEDULER_JOB_DESTS
views are also dropped. -
Jobs running against the destination are stopped.
-
Members of database destination groups that refer to the destination are removed from the group.
See Also:
150.6.36 DROP_FILE_WATCHER Procedure
This procedure drops one or more file watchers.
Syntax
DBMS_SCHEDULER.DROP_FILE_WATCHER ( file_watcher_name IN VARCHAR2, force IN BOOLEAN DEFAULT FALSE);
Parameters
Table 150-49 DROP_FILE_WATCHER Procedure Parameters
Parameter | Description |
---|---|
|
The file watcher to drop. Can be a comma-separated list of file watchers. Each file watcher name can optionally be prefixed with a schema name. Cannot be |
|
If set to |
Usage Notes
Only the owner of a file watcher or a user with the CREATE ANY JOB
system privilege may drop the file watcher.
Running jobs that point to the file watcher are not affected by this procedure and are allowed to continue.
See Also:
150.6.37 DROP_GROUP Procedure
This procedure drops one or more groups.
Syntax
DBMS_SCHEDULER.DROP_GROUP ( group_name IN VARCHAR2, force IN BOOLEAN DEFAULT FALSE);
Parameters
Table 150-50 DROP_GROUP Procedure Parameters
Parameter | Description |
---|---|
|
A group to drop. Can be a comma-separated list of group names. Each group name can optionally be prefixed with a schema name. The procedure stops processing if it encounters a group that does not exist. All groups processed before the error are dropped. Cannot be |
|
If |
Usage Notes
Only the owner or a user with the CREATE ANY JOB
system privilege may drop a group. You must have the MANAGE
SCHEDULER
privilege to drop a group of type WINDOW
.
See Also:
150.6.38 DROP_INCOMPATIBILITY Procedure
This procedure drops an existing incompatibility definition.
Syntax
DBMS_SCHEDULER.DROP_INCOMPATIBILITY ( incompatibility_name IN VARCHAR2);
Parameters
Table 150-51 DROP_INCOMPATIBILITY Procedure Parameters
Parameter | Description |
---|---|
|
The name of the incompatibility definition. |
Usage Notes
See Also:
Using Incompatibility Definitions in Oracle Database Administrator’s Guide
150.6.39 DROP_JOB Procedure
This procedure drops one or more jobs or all jobs in one or more job classes. Dropping a job also drops all argument values set for that job.
Syntax
DBMS_SCHEDULER.DROP_JOB ( job_name IN VARCHAR2, force IN BOOLEAN DEFAULT FALSE, defer IN BOOLEAN DEFAULT FALSE, commit_semantics IN VARCHAR2 DEFAULT 'STOP_ON_FIRST_ERROR');
Parameters
Table 150-52 DROP_JOB Procedure Parameters
Parameter | Description |
---|---|
|
The name of a job or job class. Can be a comma-delimited list. For a job class, the If the name of a job class is specified, the jobs that belong to that job class are dropped, but the job class itself is not dropped. |
|
If |
|
If |
|
The commit semantics. The following types are supported:
Only |
Usage Notes
If both force
and defer
are set to FALSE
and a job is running at the time of the call, the attempt to drop that job fails. The entire call to DROP_JOB
may then fail, depending on the setting of commit_semantics
.
Setting both force
and defer
to TRUE
results in an error.
Dropping a job requires ALTER
privileges on the job either as the owner of the job or as a user with the ALTER
object privilege on the job or the CREATE
ANY
JOB
system privilege.
150.6.40 DROP_JOB_CLASS Procedure
This procedure drops a job class. Dropping a job class means that all the metadata about the job class is removed from the database.
Syntax
DBMS_SCHEDULER.DROP_JOB_CLASS ( job_class_name IN VARCHAR2, force IN BOOLEAN DEFAULT FALSE);
Parameters
Table 150-53 DROP_JOB_CLASS Procedure Parameters
Parameter | Description |
---|---|
|
The name of the job class. Can be a comma-delimited list. |
|
If If Running jobs that belong to the job class are not affected. |
Usage Notes
Dropping a job class requires the MANAGE
SCHEDULER
system privilege.
150.6.41 DROP_PROGRAM Procedure
This procedure drops a program. Any arguments that pertain to the program are also dropped when the program is dropped.
Syntax
DBMS_SCHEDULER.DROP_PROGRAM ( program_name IN VARCHAR2, force IN BOOLEAN DEFAULT FALSE);
Parameters
Table 150-54 DROP_PROGRAM Procedure Parameters
Parameter | Description |
---|---|
|
The name of the program to be dropped. Can be a comma-delimited list. |
|
If If Running jobs that point to the program are not affected by the |
Usage Notes
Dropping a program requires that you be the owner of the program or have ALTER
privileges on that program. You can also drop a program if you have the CREATE
ANY
JOB
privilege.
150.6.42 DROP_PROGRAM_ARGUMENT Procedure
This procedure drops a program argument. An argument can be specified by either name (if one has been given) or position.
The procedure is overloaded.
Syntax
Drops a program argument by position:
DBMS_SCHEDULER.DROP_PROGRAM_ARGUMENT ( program_name IN VARCHAR2, argument_position IN PLS_INTEGER);
Drops a program argument by name:
DBMS_SCHEDULER.DROP_PROGRAM_ARGUMENT ( program_name IN VARCHAR2, argument_name IN VARCHAR2);
Parameters
Table 150-55 DROP_PROGRAM_ARGUMENT Procedure Parameters
Parameter | Description |
---|---|
|
The name of the program to be altered. A program with this name must exist. |
|
The name of the argument being dropped |
|
The position of the argument to be dropped |
Usage Notes
Dropping a program argument requires that you be the owner of the program or have ALTER
privileges on that program. You can also drop a program argument if you have the CREATE
ANY
JOB
privilege.
150.6.43 DROP_RESOURCE Procedure
This procedure drops a resource.
Syntax
DBMS_SCHEDULER.DROP_RESOURCE ( resource_name IN VARCHAR2, force IN BOOLEAN DEFAULT FALSE);
Parameters
Table 150-56 DROP_RESOURCE Procedure Parameters
Parameter | Description |
---|---|
|
The name of the resource to be dropped. Can be a comma-delimited list. |
|
If If |
Usage Notes
Only the owner or a user with the CREATE ANY JOB system privilege may drop the resource.
See Also:
Creating or Dropping a Resource in Oracle Database Administrator’s Guide
150.6.44 DROP_SCHEDULE Procedure
This procedure drops a schedule.
Syntax
DBMS_SCHEDULER.DROP_SCHEDULE ( schedule_name IN VARCHAR2, force IN BOOLEAN DEFAULT FALSE);
Parameters
Table 150-57 DROP_SCHEDULE Procedure Parameters
Parameter | Description |
---|---|
|
The name of the schedule. Can be a comma-delimited list. |
|
If If Running jobs and open windows that point to the schedule are not affected. |
Usage Notes
You must be the owner of the schedule being dropped or have ALTER
privileges for the schedule or the CREATE
ANY
JOB
privilege.
150.6.45 DROP_WINDOW Procedure
This procedure drops a window. All metadata about the window is removed from the database. The window is removed from any groups that reference it.
Syntax
DBMS_SCHEDULER.DROP_WINDOW ( window_name IN VARCHAR2, force IN BOOLEAN DEFAULT FALSE);
Parameters
Table 150-58 DROP_WINDOW Procedure Parameters
Parameter | Description |
---|---|
|
The name of the window. Can be a comma-delimited list. |
|
If If Running jobs that have the window as their schedule is allowed to continue, unless the |
Usage Notes
Dropping a window requires the MANAGE
SCHEDULER
privilege.
150.6.46 ENABLE Procedure
This procedure enables a program, job, chain, window, database destination, external destination, file watcher, or group.
When an object is enabled, its enabled
attribute is set to TRUE
. By default, jobs, chains, and programs are created disabled and database destinations, external destinations, file watchers, windows, and groups are created enabled.
If a job was disabled and you enable it, the Scheduler begins to automatically run the job according to its schedule. Enabling a disabled job also resets the job RUN_COUNT
, FAILURE_COUNT
and RETRY_COUNT
columns in the *_SCHEDULER_JOBS
data dictionary views.
Validity checks are performed before enabling an object. If the check fails, the object is not enabled, and an appropriate error is returned. This procedure does not return an error if the object was already enabled.
Syntax
DBMS_SCHEDULER.ENABLE ( name IN VARCHAR2, commit_semantics IN VARCHAR2 DEFAULT 'STOP_ON_FIRST_ERROR');
Parameters
Table 150-59 ENABLE Procedure Parameters
Parameter | Description |
---|---|
|
The name of the Scheduler object being enabled. Can be a comma-delimited list of names. If a job class name is specified, then all the jobs in the job class are enabled. If a group name is specified, then the group is enabled, but the enabled state of the group members is unaffected. |
|
The commit semantics. The following types are supported:
|
Usage Notes
Window names must be preceded by SYS
.
To run ENABLE
for a window or group of type WINDOW
, you must have the MANAGE
SCHEDULER
privilege. For a job of type EXECUTABLE
(or for a job that points to a program of type EXECUTABLE
), the job owner must have the CREATE EXTERNAL JOB
system privilege before the job can be enabled or run.
To enable a file watcher, the file watcher owner must have the EXECUTE
privilege on the designated credential.
You can use ENABLE
with any schema except the SYS
schema.
150.6.47 END_DETACHED_JOB_RUN Procedure
This procedure ends a detached job run. A detached job points to a detached program, which is a program with the detached
attribute set to TRUE
.
A detached job run does not end until this procedure or the STOP_JOB Procedure is called.
Syntax
DBMS_SCHEDULER.END_DETACHED_JOB_RUN ( job_name IN VARCHAR2, error_number IN PLS_INTEGER DEFAULT 0, additional_info IN VARCHAR2 DEFAULT NULL);
Parameters
Table 150-60 END_DETACHED_JOB_RUN Procedure Parameters
Parameter | Description |
---|---|
|
The name of the job to end. Must be a detached job that is running. |
|
If zero, then the job run is logged as succeeded. If -1013, then the job run is logged as stopped. If any other number, then the job run is logged as failed with that error number. |
|
This text is stored in the |
Usage Notes
This procedure requires that you either own the job or have ALTER
privileges on it. You can also end any detached job run if you have the CREATE
ANY
JOB
privilege.
See Also:
Oracle Database Administrator's Guide for information about detached jobs.
150.6.48 EVALUATE_CALENDAR_STRING Procedure
You can define repeat intervals of jobs, windows or schedules using the Scheduler calendaring syntax. This procedure evaluates the calendar expression and tells you the next execution date and time of a job or window. This is very useful for testing the correct definition of the calendar string without actually scheduling the job or window.
This procedure can also get multiple steps of the repeat interval by passing the next_run_date
returned by one invocation as the return_date_after
argument of the next invocation.
See the calendaring syntax described in "Operational Notes".
Syntax
DBMS_SCHEDULER.EVALUATE_CALENDAR_STRING ( calendar_string IN VARCHAR2, start_date IN TIMESTAMP WITH TIME ZONE, return_date_after IN TIMESTAMP WITH TIME ZONE, next_run_date OUT TIMESTAMP WITH TIME ZONE);
Parameters
Table 150-61 EVALUATE_CALENDAR_STRING Procedure Parameters
Parameter | Description |
---|---|
|
The calendar expression to be evaluated. The string must be in the calendaring syntax described in "Operational Notes". |
|
The date and time after which the repeat interval becomes valid. It can also be used to fill in specific items that are missing from the calendar string. Can optionally be |
|
The return_date_after argument helps the Scheduler determine which one of all possible matches (all valid execution dates) to return from those determined by the When a |
|
The first timestamp that matches the calendar string and start date that occur after the value passed in for the |
Examples
The following code fragment can be used to determine the next five dates a job will run given a specific calendar string.
SET SERVEROUTPUT ON;
ALTER SESSION set NLS_DATE_FORMAT = 'DD-MON-YYYY HH24:MI:SS';
Session altered.
DECLARE
start_date TIMESTAMP;
return_date_after TIMESTAMP;
next_run_date TIMESTAMP;
BEGIN
start_date :=
to_timestamp_tz('01-JAN-2003 10:00:00','DD-MON-YYYY HH24:MI:SS');
return_date_after := start_date;
FOR i IN 1..5 LOOP
DBMS_SCHEDULER.EVALUATE_CALENDAR_STRING(
'FREQ=DAILY;BYHOUR=9;BYMINUTE=30;BYDAY=MON,TUE,WED,THU,FRI',
start_date, return_date_after, next_run_date);
DBMS_OUTPUT.PUT_LINE('next_run_date: ' || next_run_date);
return_date_after := next_run_date;
END LOOP;
END;
/
next_run_date: 02-JAN-03 09.30.00.000000 AM
next_run_date: 03-JAN-03 09.30.00.000000 AM
next_run_date: 06-JAN-03 09.30.00.000000 AM
next_run_date: 07-JAN-03 09.30.00.000000 AM
next_run_date: 08-JAN-03 09.30.00.000000 AM
PL/SQL procedure successfully completed.
Usage Notes
No specific Scheduler privileges are required.
150.6.49 EVALUATE_RUNNING_CHAIN Procedure
This procedure forces reevaluation of the rules of a running chain to trigger any rules for which the conditions have been satisfied. The job passed as an argument must point to a chain and must be running. If the job is not running, an error is thrown. (RUN_JOB
can be used to start the job.)
If any of the steps of the chain are themselves running chains, another EVALUATE_RUNNING_CHAIN
is performed on each of the nested running chains.
Syntax
DBMS_SCHEDULER.EVALUATE_RUNNING_CHAIN ( job_name IN VARCHAR2);
Parameters
Table 150-62 EVALUATE_RUNNING_CHAIN Procedure Parameter
Parameter | Description |
---|---|
|
The name of the running job (pointing to a chain) to reevaluate the rules for |
Usage Notes
Running EVALUATE_RUNNING_CHAIN
on a job requires alter privileges on the job (either as the owner, or as a user with ALTER
privileges on the job or the CREATE
ANY
JOB
system privilege).
Note:
The Scheduler automatically evaluates a chain:
-
At the start of the chain job
-
When a chain step completes
-
When an event occurs that is associated with an event step in the chain
For most chains, this is sufficient. EVALUATE_RUNNING_CHAIN
should be used only under the following circumstances:
-
After manual intervention of a running chain with the
ALTER_RUNNING_CHAIN
procedure -
When chain rules use SQL syntax and the rule conditions contain elements that are not under the control of the Scheduler.
In these cases, EVALUATE_RUNNING_CHAIN
may not be needed if you set the evaluation_interval
attribute when you created the chain.
150.6.50 GENERATE_JOB_NAME Function
This function returns a unique name for a job.
The name will be of the form {prefix}N
where N
is a number from a sequence. If no prefix is specified, the generated name will, by default, be JOB$_1
, JOB$_2
, JOB$_3
, and so on. If 'SCOTT'
is specified as the prefix, the name will be SCOTT1
, SCOTT2
, and so on.
Syntax
DBMS_SCHEDULER.GENERATE_JOB_NAME ( prefix IN VARCHAR2 DEFAULT 'JOB$_') RETURN VARCHAR2;
Parameters
Table 150-63 GENERATE_JOB_NAME Function Parameter
Parameter | Description |
---|---|
|
The prefix to use when generating the job name |
Usage Notes
If the prefix is explicitly set to NULL
, the name is just the sequence number. In order to successfully use such numeric names, they must be surrounded by double quotes throughout the DBMS_SCHEDULER
calls. A prefix cannot be longer than 18 characters and cannot end with a digit.
Note that, even though the GENERATE_JOB_NAME
function never returns the same job name twice, there is a small chance that the returned name matches an already existing database object.
No specific Scheduler privileges are required to use this function.
150.6.51 GET_AGENT_INFO Function
This function can return job information specific to an agent, such as how many are running and so on, depending on the attribute selected.
Syntax
DBMS_SCHEDULER.GET_AGENT_INFO ( agent_name IN VARCHAR2, attribute IN VARCHAR2) RETURN VARCHAR2;
Parameters
Table 150-64 GET_AGENT_INFO Function Parameter
Parameter | Description |
---|---|
|
The name of an external destination where the agent is running |
|
Possible Attributes values
|
Usage Notes
This function returns the same information as the schagent
utility status option. See Oracle Database Administrator's Guide.
150.6.52 GET_AGENT_VERSION Function
This function returns the version string of a Scheduler agent that is registered with the database and is currently running. GET_AGENT_VERSION
throws an error if the agent is not registered with the database or if the agent is not currently running.
Syntax
DBMS_SCHEDULER.GET_AGENT_VERSION ( agent_host IN VARCHAR2) RETURN VARCHAR2;
Parameters
Table 150-65 GET_AGENT_VERSION Function Parameter
Parameter | Description |
---|---|
|
Either the hostname and port on which the agent is running in the form |
Usage Notes
This function requires the CREATE
EXTERNAL
JOB
system privilege.
150.6.53 GET_ATTRIBUTE Procedure
This procedure retrieves the value of an attribute of a Scheduler object. It is overloaded to retrieve values of various types.
Syntax
DBMS_SCHEDULER.GET_ATTRIBUTE ( name IN VARCHAR2, attribute IN VARCHAR2, value OUT {VARCHAR2|PLS_INTEGER|BOOLEAN|DATE|TIMESTAMP| TIMESTAMP WITH TIME ZONE|TIMESTAMP WITH LOCAL TIME ZONE| INTERVAL DAY TO SECOND}); DBMS_SCHEDULER.GET_ATTRIBUTE ( name IN VARCHAR2, attribute IN VARCHAR2, value OUT VARCHAR2, value2 OUT VARCHAR2);
Parameters
Table 150-66 GET_ATTRIBUTE Procedure Parameters
Parameter | Description |
---|---|
|
The name of the object |
|
The attribute being retrieved. See the SET_ATTRIBUTE Procedure for tables of attribute values. |
|
The existing value of the attribute |
|
The Most attributes have only one value associated with them, but some can have two. |
Usage Notes
To run GET_ATTRIBUTE
for a job class, you must have the MANAGE
SCHEDULER
privilege or have EXECUTE
privileges on the class. For a schedule, window, or group, no privileges are necessary. Otherwise, you must be the owner of the object or have ALTER
or EXECUTE
privileges on that object or have the CREATE ANY JOB
privilege.
See the SET_ATTRIBUTE Procedure for tables of attribute values that you can retrieve for the various Scheduler object types.
150.6.54 GET_FILE Procedure
This procedure retrieves a file from the operating system file system of a specified host. The file is copied to a destination, or its contents are returned in a procedure output parameter.
You can also use this procedure to retrieve the standard output or error text for a run of an external job that has an associated credential.
This procedures differs from the equivalent UTL_FILE
procedure in that it uses a credential and can retrieve files from remote hosts that have only a Scheduler agent (and not an Oracle database) installed.
Syntax
DBMS_SCHEDULER.GET_FILE ( source_file IN VARCHAR2, source_host IN VARCHAR2, credential_name IN VARCHAR2, file_contents IN OUT NOCOPY {BLOB|CLOB});
DBMS_SCHEDULER.GET_FILE ( source_file IN VARCHAR2, source_host IN VARCHAR2, credential_name IN VARCHAR2, destination_file_name IN VARCHAR2, destination_directory_object IN VARCHAR2, destination_permissions IN VARCHAR2 DEFAULT NULL);
Parameters
Table 150-67 GET_FILE Procedure Parameters
Parameter | Description |
---|---|
|
Fully qualified path name of the file to retrieve from the operating system. The file name is case-sensitive and is not converted to uppercase. If the file name starts with a question mark (' If the format of this parameter is If the format of this parameter is You obtain the value of The external job must have an associated credential. The |
|
If the file is to be retrieved from a remote host, then this parameter must be a valid an external destination name. (An external destination is created when you register a remote Scheduler agent with the database. You can view external destination names in the views If |
|
The name of the credential to use for accessing the file system. |
|
The variable into which the file contents is read. |
|
The file to which the file contents is written. |
|
The directory object that specifies the path to the destination file, when |
|
Reserved for future use |
Usage Notes
The caller must have the CREATE EXTERNAL JOB
system privilege and have EXECUTE
privileges on the credential.
150.6.55 GET_SCHEDULER_ATTRIBUTE Procedure
This procedure retrieves the value of a Scheduler attribute.
Syntax
DBMS_SCHEDULER.GET_SCHEDULER_ATTRIBUTE ( attribute IN VARCHAR2, value OUT VARCHAR2);
Parameters
Table 150-68 GET_SCHEDULER_ATTRIBUTE Procedure Parameters
Parameter | Description |
---|---|
|
The name of the attribute |
|
The existing value of the attribute |
Usage Notes
To run GET_SCHEDULER_ATTRIBUTE
, you must have the MANAGE
SCHEDULER
privilege.
Table 150-69 lists the Scheduler attributes that you can retrieve. For more detail on these attributes, see Table 150-101 and the section "Configuring the Scheduler" in Oracle Database Administrator's Guide.
Table 150-69 Scheduler Attributes Retrievable with GET_SCHEDULER_ATTRIBUTE
Scheduler Attribute | Description |
---|---|
|
Name of the currently open window |
|
Default time zone used by the Scheduler for repeat intervals and windows |
|
The default e-mail address of the sender for job state e-mail notifications |
|
The SMTP server address that the Scheduler uses to send e-mail notifications for job state events. E-mail notifications cannot be sent if this attribute is |
|
Time in seconds before an event generated by the Scheduler and enqueued onto the Scheduler event queue expires. May be |
|
Retention period in days for job and window logs. The range of valid values is 0 through 1000000. |
|
This Scheduler attribute is not used. |
150.6.56 OPEN_WINDOW Procedure
This procedure manually opens a window, unrelated to its schedule.
The window opens and the resource plan associated with it takes effect immediately, for the duration specified or for the normal duration of the window, if no duration is given. Only an enabled window can be manually opened.
Syntax
DBMS_SCHEDULER.OPEN_WINDOW ( window_name IN VARCHAR2, duration IN INTERVAL DAY TO SECOND, force IN BOOLEAN DEFAULT FALSE);
Parameters
Table 150-70 OPEN_WINDOW Procedure Parameters
Parameter | Description |
---|---|
|
The name of the window |
|
The duration of the window. It is of type interval day to second. If it is |
|
If If You can open a window that is already open. The window stays open for the duration specified in the call, from the time the For example: The Scheduler automatically closes any window that is open at that time, even if it has a higher priority. For the duration of this manually opened window, the Scheduler does not open any other scheduled windows even if they have a higher priority. |
Usage Notes
Opening a window manually has no impact on regular scheduled runs of the window. The next open time of the window is not updated and is determined by the regular scheduled opening.
When a window that was manually opened closes, the rules about overlapping windows are applied to determine which other window should be opened at that time if any at all.
If there are jobs running when the window opens, the resources allocated to them might change if there is a switch in resource plan.
If a window fails to switch resource plans because the designated resource plan no longer exists or because resource plan switching by windows is disabled (for example, by using the ALTER
SYSTEM
statement with the force
option), the failure to switch resource plans is recorded in the window log.
Opening a window requires the MANAGE
SCHEDULER
privilege.
150.6.57 PURGE_LOG Procedure
The PURGE_LOG
procedure purges rows from the job and window log that were not purged automatically by the scheduler.
By default, the Scheduler automatically purges all rows in the job log and window log that are older than 30 days. The PURGE_LOG
procedure can be used to purge additional rows from the job and window log.
Rows in the job log table pertaining to the steps of a chain are purged only when the entry for the main chain job is purged (either manually or automatically).
Syntax
DBMS_SCHEDULER.PURGE_LOG ( log_history IN PLS_INTEGER DEFAULT 0, which_log IN VARCHAR2 DEFAULT 'JOB_AND_WINDOW_LOG', job_name IN VARCHAR2 DEFAULT NULL);
Parameters
Table 150-71 PURGE_LOG Procedure Parameters
Parameter | Description |
---|---|
|
This specifies how much history (in days) to keep. The valid range is 0 - 1000000. If set to 0, no history is kept. |
|
This specifies the log type. Valid values are: |
|
This specifies which job-specific entries must be purged from the jog log. This can be a comma-delimited list of job names and job classes. Whenever |
Usage Notes
This procedure requires the MANAGE
SCHEDULER
privilege.
Examples
The following completely purges all rows from both the job log and the window log:
DBMS_SCHEDULER.PURGE_LOG();
The following purges all rows from the window log that are older than 5 days:
DBMS_SCHEDULER.PURGE_LOG(5, 'window_log');
The following purges all rows from the window log that are older than 1 day and all rows from the job log that are related to jobs in jobclass1
and older than 1 day:
DBMS_SCHEDULER.PURGE_LOG(1, 'job_and_window_log', 'sys.jobclass1');
150.6.58 PUT_FILE Procedure
This procedure saves a file to the operating system file system of a specified remote host or of the local computer.
It differs from the equivalent UTL_FILE
procedure in that it uses a credential and can save files to a remote host that has only a Scheduler agent (and not an Oracle Database) installed.
Syntax
DBMS_SCHEDULER.PUT_FILE ( destination_file IN VARCHAR2, destination_host IN VARCHAR2, credential_name IN VARCHAR2, file_contents IN {BLOB|CLOB}, destination_permissions IN VARCHAR2 DEFAULT NULL);
DBMS_SCHEDULER.PUT_FILE ( destination_file IN VARCHAR2, destination_host IN VARCHAR2, credential_name IN VARCHAR2, source_file_name IN VARCHAR2, source_directory_object IN VARCHAR2, destination_permissions IN VARCHAR2 DEFAULT NULL);
Parameters
Table 150-72 PUT_FILE Procedure Parameters
Parameter | Description |
---|---|
|
Fully qualified path name of the file to save to the operating system file system. The file name is case-sensitive. If the file name starts with a question mark (' |
|
If To save to a remote host, this parameter must be a valid external destination name. (An external destination is created when you register a remote Scheduler agent with the database. You can view external destination names in the views |
|
The name of the credential to use for accessing the destination file system. |
|
The variable from which the file contents is read. |
|
The file from which the file contents is written |
|
The directory object that specifies the path to the source file, when |
|
Reserved for future use |
Usage Notes
The caller must have the CREATE EXTERNAL JOB
system privilege and have EXECUTE
privileges on the credential.
150.6.59 REMOVE_EVENT_QUEUE_SUBSCRIBER Procedure
This procedure unsubscribes a user from the Scheduler event queue SYS.SCHEDULER$_EVENT_QUEUE
.
Syntax
DBMS_SCHEDULER.REMOVE_EVENT_QUEUE_SUBSCRIBER ( subscriber_name IN VARCHAR2 DEFAULT NULL);
Parameters
Table 150-73 REMOVE_EVENT_QUEUE_SUBSCRIBER Procedure Parameters
Parameter | Description |
---|---|
|
Name of the Oracle Advanced Queuing (AQ) agent to remove the subscription from. If |
Usage Notes
After the agent is unsubscribed, it is deleted. If the agent does not exist or is not currently subscribed to the Scheduler event queue, an error is raised.
150.6.60 REMOVE_FROM_INCOMPATIBILITY Procedure
This procedure removes jobs or programs from an existing incompatibility definition.
Syntax
DBMS_SCHEDULER.REMOVE_FROM_INCOMPATIBILITY ( incompatibility_name IN VARCHAR2, object_name IN VARCHAR2);
Parameters
Table 150-74 REMOVE_FROM_INCOMPATIBILITY Procedure Parameters
Parameter | Description |
---|---|
|
The name of the incompatibility definition. |
|
One or more (comma-separated) programs or jobs |
Usage Notes
This procedure does not raise an error if any specified objects do not already exist in the incompatibility definition.
See Also:
Using Incompatibility Definitions in Oracle Database Administrator’s Guide
150.6.61 REMOVE_GROUP_MEMBER Procedure
This procedure removes one or more members from an existing group.
Syntax
DBMS_SCHEDULER.REMOVE_GROUP_MEMBER ( group_name IN VARCHAR2, member IN VARCHAR2);
Parameters
Table 150-75 REMOVE_GROUP_MEMBER Procedure Parameters
Parameter | Description |
---|---|
|
The name of the group. |
|
The name of the member to remove from group. Comma-separated list of members to remove. An error is returned if any of the members is not part of the group. A group of the same type can be named as a member. The Scheduler immediately expands the included group name into its list of members. If the member is a destination, any job instances that run on this destination are removed from the |
Usage Notes
The following users may remove members from a group:
-
The group owner
-
A user that has been granted the
ALTER
object privilege on the group -
A user with the
CREATE ANY JOB
system privilege
You must have the MANAGE
SCHEDULER
privilege to remove a member from a group of type WINDOW
.
See Also:
150.6.62 REMOVE_JOB_EMAIL_NOTIFICATION Procedure
This procedure removes e-mail notifications for a job. You can remove all e-mail notifications or remove notifications only for specified recipients or specified events.
Syntax
DBMS_SCHEDULER.REMOVE_JOB_EMAIL_NOTIFICATION ( job_name IN VARCHAR2, recipients IN VARCHAR2 DEFAULT NULL, events IN VARCHAR2 DEFAULT NULL);
Parameters
Table 150-76 ADD_JOB_EMAIL_NOTIFICATION Procedure Parameters
Parameter | Description |
---|---|
|
Name of the job to remove e-mail notifications for. Cannot be |
|
E-mail address to remove e-mail notification for. Comma-separated list of e-mail addresses. |
|
Job state event to remove e-mail notification for. Comma-separate list of job state events. |
Usage Notes
When you specify multiple recipients and multiple events, the notification for each specified event is removed for each specified recipient. The procedure ignores any recipients or events that are specified but that were not previously added.
If recipients
is NULL
, e-mail notifications for the specified events are removed for all existing recipients. If events
is NULL
, notifications for all events are removed for the specified recipients. If both recipients
and events
are NULL
, all e-mail notifications are removed for the job.
For example, if recipients
is 'jsmith@example.com,rjones@example.com
' and events
is 'JOB_FAILED,JOB_BROKEN
', then notifications for both the JOB_FAILED
and JOB_BROKEN
events are removed for both jsmith and rjones. If recipients
is NULL
, then notifications for both the JOB_FAILED
and JOB_BROKEN
events are removed for jsmith, rjones, and any other previously defined recipients for these events.
To call this procedure, you must be the job owner or a user with the CREATE
ANY
JOB
system privilege or ALTER
object privilege on the job.
See Also:
150.6.63 RESET_JOB_ARGUMENT_VALUE Procedure
This procedure resets (clears) the value previously set to an argument for a job.
RESET_JOB_ARGUMENT_VALUE
is overloaded.
Syntax
Clears a previously set job argument value by argument position:
DBMS_SCHEDULER.RESET_JOB_ARGUMENT_VALUE ( job_name IN VARCHAR2, argument_position IN PLS_INTEGER);
Clears a previously set job argument value by argument name:
DBMS_SCHEDULER.RESET_JOB_ARGUMENT_VALUE ( job_name IN VARCHAR2, argument_name IN VARCHAR2);
Parameters
Table 150-77 RESET_JOB_ARGUMENT_VALUE Procedure Parameters
Parameter | Description |
---|---|
|
The name of the job being altered |
|
The position of the program argument being reset |
|
The name of the program argument being reset |
Usage Notes
If the corresponding program argument has no default value, the job is disabled. Resetting a program argument of a job belonging to another user requires ALTER
privileges on that job. Arguments can be specified by position or by name.
RESET_JOB_ARGUMENT_VALUE
requires that you be the owner of the job or have ALTER
privileges on that job. You can also reset a job argument value if you have the CREATE
ANY
JOB
privilege.
RESET_JOB_ARGUMENT_VALUE
only supports arguments of SQL type. Therefore, argument values that are not of SQL type, such as booleans, are not supported as program or job arguments.
150.6.64 RUN_CHAIN Procedure
This procedure immediately runs a chain or part of a chain by creating a run-once job with the job name given.
If no job_name
is given, one is generated of the form RUN_CHAIN$_
chainname
N
, where chainname
is the first 8 characters of the chain name and N is an integer.
If a list of start steps is given, only those steps are started when the chain begins running. Steps not in the list that would normally have started are skipped and paused (so that they or the steps after them do not run).
If start_steps
is NULL
, then the chain starts normally—that is, it performs an initial evaluation to see which steps to start running).
If a list of initial step states is given, the newly created chain job sets every listed step to the state specified for that step before evaluating the chain rules to see which steps to start. (Steps in the list are not started.)
Syntax
Runs a chain, with a list of start steps.
DBMS_SCHEDULER.RUN_CHAIN ( chain_name IN VARCHAR2, start_steps IN VARCHAR2, job_name IN VARCHAR2 DEFAULT NULL);
Runs a chain, with a list of initial step states.
DBMS_SCHEDULER.RUN_CHAIN ( chain_name IN VARCHAR2, step_state_list IN SYS.SCHEDULER$_STEP_TYPE_LIST, job_name IN VARCHAR2 DEFAULT NULL);
Parameters
Table 150-78 RUN_CHAIN Procedure Parameters
Parameter | Description |
---|---|
|
The name of the chain to run |
|
The name of the job to create to run the chain |
|
Comma-separated list of the steps to start when the chain starts running |
|
List of chain steps with an initial state ( Set the attributes of
where error_number is a positive or negative integer. |
Usage Notes
Running a chain requires CREATE
JOB
if the job is being created in the user's schema, or CREATE
ANY
JOB
otherwise. In addition, the owner of the job being created needs execute privileges on the chain (as the owner of the chain, or as a user with the EXECUTE
privilege on the chain or the EXECUTE
ANY
PROGRAM
system privilege).
Examples
The following example illustrates how to start a chain in the middle by providing the initial state of some chain steps.
declare initial_step_states sys.scheduler$_step_type_list; begin initial_step_states := sys.scheduler$_step_type_list( sys.scheduler$_step_type('step1', 'SUCCEEDED'), sys.scheduler$_step_type('step2', 'FAILED 27486'), sys.scheduler$_step_type('step3', 'SUCCEEDED'), sys.scheduler$_step_type('step5', 'SUCCEEDED')); dbms_scheduler.run_chain('my_chain', initial_step_states); end; /
150.6.65 RUN_JOB Procedure
This procedure runs a job immediately.
If a job is enabled, the Scheduler runs it automatically. It is not necessary to call RUN_JOB
to run a job according to its schedule. Use RUN_JOB
to run a job outside of its normal schedule.
Syntax
DBMS_SCHEDULER.RUN_JOB ( job_name IN VARCHAR2, use_current_session IN BOOLEAN DEFAULT TRUE);
Parameters
Table 150-79 RUN_JOB Procedure Parameters
Parameter | Description |
---|---|
|
A job name or a comma-separate list of entries, where each is the name of an existing job, optionally preceded by a schema name and dot separator. If you specify a multiple-destination job, the job runs on all destinations. In this case, the |
|
This specifies whether or not the job run should occur in the same session that the procedure was invoked from.The job always runs as the job owner, in the job owner's schema, unless it has credential specified, then the job runs using the user named in the credential. When
When
For jobs that have a specified destination or destination group, or point to chains or programs with the detached attribute set to |
Usage Notes
Jobs do not have to be enabled. If a job is disabled, the following validity checks are performed before running it:
-
The job points to a valid job class.
-
The job owner has
EXECUTE
privileges on the job class. -
If a program or chain is referenced, the program/chain exists.
-
If a program or chain is referenced, the job owner has privileges to execute the program/chain.
-
All argument values have been set (or have defaults).
-
The job owner has the
CREATE EXTERNAL JOB
privilege if this is an external job.
A TRUE
value for use_current_session
is not permitted for the following types of jobs:
-
Jobs that specify a destination or destination group in the
destination_name
attribute -
Jobs that point to chains (chain jobs)
-
Jobs that make use of detached programs (detached jobs).
above bug fix 1261887 6.12.11
When use_current_session
is TRUE
, the call to RUN_JOB
blocks until the job completes. Any errors that occur during the execution of the job are returned as errors to the RUN_JOB
procedure.
Using RUN_JOB
with use_current_session
=TRUE
does not update the job state and the job will not appear in *_SCHEDULER_RUNNING_JOBS
views.
above bug fix 19185117 9.15.14
When use_current_session
is FALSE
, RUN_JOB
returns immediately and the job is picked up by the job coordinator and passed on to a job slave for execution. The Scheduler views and logs must be queried for the outcome of the job.
Multiple user sessions can use RUN_JOB
in their sessions simultaneously when use_current_session
is set to TRUE
.
RUN_JOB
requires that you own the job or have ALTER
privileges on that job. You can also run a job if you have the CREATE
ANY
JOB
privilege.
Example
The following is an example of using RUN_JOB
.
BEGIN DBMS_SCHEDULER.RUN_JOB( JOB_NAME => 'EODJOB, DSS.ETLJOB', USE_CURRENT_SESSION => FALSE); END;
150.6.66 SET_AGENT_REGISTRATION_PASS Procedure
This procedure sets the agent registration password for a database.
A Scheduler agent must register with the database before the database can submit jobs to the agent. The agent must provide this password when registering.
Syntax
DBMS_SCHEDULER.SET_AGENT_REGISTRATION_PASS ( registration_password IN VARCHAR2, expiration_date IN TIMESTAMP WITH TIME ZONE DEFAULT NULL, max_uses IN NUMBER DEFAULT NULL);
Parameters
Table 150-80 SET_AGENT_REGISTRATION_PASS Procedure Parameters
Parameter | Description |
---|---|
|
This is the password that remote agents must specify in order to successfully register with the database. If this is |
|
If this is set to a non- |
|
This is the maximum number of successful registrations that can be performed with this password. After the number of successful registrations has been performed with this password, then no agents can register with the database. This cannot be set to 0 or a negative value. If this is set to |
Usage Notes
To prevent abuse, this password can be set to expire after a given date or a maximum number of successful registrations. This procedure will overwrite any password already set. This requires the MANAGE SCHEDULER
system privilege.
By default, max_uses
is set to NULL
, which means that there is no limit to the number of successful registrations.
Oracle recommends that an agent registration password be reset after every agent registration or every known set of agent registrations. Furthermore, Oracle recommends that this password be set to NULL
if no new agents are being registered.
150.6.67 SET_ATTRIBUTE Procedure
This procedure modifies an attribute of a Scheduler object. It is overloaded to accept values of various types.
To set an attribute to NULL
, use the SET_ATTRIBUTE_NULL
procedure. The attributes that can be set depend on the object being altered. All object attributes can be changed, except the object name.
Syntax
DBMS_SCHEDULER.SET_ATTRIBUTE ( name IN VARCHAR2, attribute IN VARCHAR2, value IN {BOOLEAN|DATE|TIMESTAMP| TIMESTAMP WITH TIME ZONE|TIMESTAMP WITH LOCAL TIME ZONE| INTERVAL DAY TO SECOND}); DBMS_SCHEDULER.SET_ATTRIBUTE ( name IN VARCHAR2, attribute IN VARCHAR2, value IN VARCHAR2, value2 IN VARCHAR2 DEFAULT NULL);
Parameters
Table 150-81 SET_ATTRIBUTE Procedure Parameters
Parameter | Description |
---|---|
|
The name of the object. |
|
See Table 150-83 through Table 150-93. |
|
The new value being set for the attribute. This cannot be |
|
The |
Table 150-82 is a directory of Scheduler object types and tables of attributes for the object types.
These object types can be viewed with Scheduler Data Dictionary Views, listed in Oracle Database Administrator's Guide.
Table 150-82 Attribute Tables for Scheduler Object Types
Scheduler Object Type | Table of Attributes |
---|---|
Job |
|
Program |
|
Schedule |
|
File Watcher |
|
Job Class |
|
Window |
|
Chain |
|
Database Destination |
|
External Destination |
|
Group |
|
Credential |
|
Resource |
Usage Notes
If an object is altered and it was in the enabled state, the Scheduler first disables it, then makes the change and reenables it. If any errors are encountered during the enable process, the object is not reenabled and an error is generated.
If an object is altered and it was in the disabled state, it remains disabled after it is altered.
To run SET_ATTRIBUTE
for a window, a group of type WINDOW
, or job class, you must have the MANAGE
SCHEDULER
privilege. Otherwise, you must be the owner of the object being altered or have ALTER
privileges on that object or have the CREATE
ANY
JOB
privilege.
Job
If there is a running instance of the job when the SET_ATTRIBUTE
call is made, it is not affected by the call. The change is only affects future runs of the job.
If any of the schedule attributes of a job are altered while the job is running, the time of the next job run is scheduled using the new schedule attributes. Schedule attributes of a job include schedule_name
, start_date
, end_date
, and repeat_interval
.
If any of the program attributes of a job are altered while the job is running, the new program attributes take effect the next time the job runs. Program attributes of a job include program_name
, job_action
, job_type
, and number_of_arguments
.
If any job argument values are altered while the job is running, the new values take effect the next time the job runs.
Granting the ALTER
privilege on a job lets a user alter all attributes of that job except its program attributes (program_name
, job_type
, job_action
, program_action
, and number_of_arguments
) and does not allow a user to use a PL/SQL expression to specify the schedule for a job.
Oracle recommends that you not alter a job that was automatically created for you by the database. Jobs that were created by the database have the column SYSTEM
set to TRUE
in job views.
Program
If any currently running jobs use the program that was altered, they continue to run with the program definition prior to the alter. The job runs with the new program definition the next time the job executes.
Schedule
If a schedule is altered, the change does not affect running jobs and open windows that use this schedule. The change only goes into effect the next time the jobs runs or the window opens.
File Watcher
If a file watcher is altered, any currently running event-based jobs started by the file arrival event are not affected. On the local system, the new file watcher attributes take effect the next time that the file watcher checks for the arrival of the file (every ten minutes by default). On remote systems, there may be an additional delay before the new file watcher attributes take effect.
Job Class
With the exception of the default job class, all job classes can be altered. To alter a job class, you must have the MANAGE
SCHEDULER
privilege.
When a job class is altered, running jobs that belong to the class are not affected. The change only takes effect for jobs that have not started running yet.
Window
When a window is altered, it does not affect an active window. The changes only take effect the next time the window opens.
If there is no current resource plan, when a window with a designated resource plan opens, the Resource Manager activates with that plan.
Job Attribute Values
Table 150-83 lists attribute values for jobs.
Note:
See the CREATE_JOB
procedure and the CREATE_JOBS
procedure for more complete descriptions of the attributes in this table.
Table 150-83 Job Attribute Values
Name | Description |
---|---|
|
If |
|
This attribute, if
A job is automatically disabled when it has failed If this attribute is set to By default, jobs are created with |
|
An optional comment. |
|
feature 25230 This attribute may be set to point to a database credential. For a SQL*Plus or backup script job, the credential connects to the database before running the script. For other job types, it is ignored. The job owner must have execute privileges on the credential, otherwise the job fails. Using a |
|
This attribute specifies the name of the credential object (credential) to use for a remote database job, a remote external job, a local external job, or an event-based job that processes a file arrival event. For local external jobs only, if this attribute is |
|
This attribute applies when the database participates in an Oracle Data Guard environment. If this attribute is set to ' Note: If you want a job to run for all database roles on a particular host, you must create two copies of the job on that host: one with a |
|
*** Deprecated in Oracle Database 11g Release 2. Use This attribute specifies a host on which to run a remote external job. It must be set to the host name or IP address of the destination host. It can optionally be followed by a port number, in the following format: hostname:port This attribute is set to |
|
The database destination or external destination for the job. Use for remote database jobs and remote external jobs only. For jobs running on the local database or for local external jobs (executables), must be See Table 150-28 for details about this attribute. |
|
Specifies the date and time after which the job expires and is no longer run. After the If no value for The value for |
|
This attribute takes two values: the |
|
If For example, if the job was set to run at 02:00 in the previous time zone, it will run at 02:00 in the new time zone. If the job If Summer and winter transitions do not change the default time zone name. |
|
Valid only in an Oracle Real Application Clusters environment. Indicates the instance on which the job is to be run. |
|
This attribute should only be used for a database running in an Oracle Real Application Clusters (Oracle RAC) environment. By default, it is set to If For environments other than Oracle RAC, this attribute is not useful because there is only one instance. |
|
The action that the job performs, depending on the |
|
The class this job is associated with. |
|
This attribute specifies the priority of this job relative to other jobs in the same class as this job. If multiple jobs within a class are scheduled to be executed at the same time, the job priority determines the order in which jobs from that class are picked up for execution by the job coordinator. It can be a value from 1 through 5, with 1 being the first to be picked up for job execution. If no job priority is specified when creating a job, the default priority of 3 is assigned to it. |
|
The type of this job.Valid values are: ' If this is set, |
|
*** Deprecated in Oracle Database 11gR2. Do not change the value of this attribute from the default, which is 1. Weight of the job for parallel execution. |
|
This attribute specifies how much information is logged. The possible options are:
(The default) No logging is performed for this job. However, the logging level of the job class takes precedence and job logging may occur.
The Scheduler logs only jobs that failed, with the reason for failure. If the job class has a higher logging level, then the higher logging level takes precedence.
The Scheduler writes detailed information to the job log for all runs of each job in this class. If the job class has a higher logging level, then the higher logging level takes precedence.
In addition to recording every run of a job, the Scheduler records all operations performed on the job, including create, enable, disable, alter (with |
|
This attribute specifies the number of times a job can fail on consecutive scheduled runs before it is automatically disabled. Once a job is disabled, it is no longer executed and its
|
|
This attribute specifies the maximum amount of time that the job should be allowed to run. Its datatype is |
|
This attribute specifies the maximum number of consecutive scheduled runs of the job. Once
|
|
The number of arguments if the program is inlined. If this is set, |
|
This is a boolean attribute that can be set only for event-based jobs. If If The lightweight jobs are not visible in any of the |
|
The name of a program object to use with this job. If this is set, |
|
This attribute tells the Scheduler at what stages of the job execution to raise events. It is a bit vector in which zero or more of the following bits can be set. Each bit has a package constant corresponding to it.
Table 150-84 describes these event types in detail. |
|
Either a PL/SQL function returning the next date and time on which to run, or calendaring syntax expression. If this is set, |
|
This attribute specifies whether or not a job can be restarted in case of failure. By default, jobs are not restartable and this attribute is set to In the case of a chain job, if this attribute is Note that setting this attribute to Retries on errors are not counted as regular runs. The run count or failure count is not incremented until the job succeeds or has failed all its six retries. The restartable attribute is used by the Scheduler to determine whether to retry the job not only on regular application errors, but after a database malfunction as well. The Scheduler retries the job a maximum of six times. The first time, it waits for one second and multiplies this wait time with a factor of 10 each time thereafter. Both the run count and failure count are incremented by 1 if the job has failed all its six retries. If the job immediately succeeds, or it succeeds on one of its retries, run count is incremented by 1. The Scheduler stops retrying a job when:
The Scheduler no longer retries the job if the next scheduled retry is past the next regularly scheduled run for repeating jobs. |
|
In heavily loaded systems, jobs are not always started at their scheduled time. This attribute enables you to have the Scheduler not start a job at all if the delay in starting the job is larger than the interval specified. It can be a value of 1 minute to 99 days. For example, if a job was supposed to start at noon and the schedule limit is set to 60 minutes, the job will not be run if it has not started to run by 1:00 p.m. If |
|
The name of a schedule, window, or group of type |
|
The original date and time on which this job started or is scheduled to start. If this is set, |
|
This attribute only applies if the schedule of a job is a window or a window group. Setting this attribute to By default, Note that, although the job is allowed to continue, its resource allocation will probably change because closing a window generally also implies a change in resource plans. |
|
This is a boolean attribute. If set to |
The following event types are valid values for the raise_events
attribute in Table 150-83.
Table 150-84 Event Types Raised by the Scheduler
Event Type | Description |
---|---|
|
Not an event, but a constant that provides an easy way for you to enable all events |
|
The job has been disabled and has changed to the |
|
A job running a chain is in the |
|
The job completed because it reached its |
|
The job was disabled by the Scheduler or by a call to |
|
The job failed, either due to an error or an abnormal termination. |
|
The job exceeded the maximum run duration specified by its |
|
A job run either failed, succeeded, or was stopped |
|
The schedule limit of the job was reached. The job was not started because the delay in starting the job exceeded the value of the |
|
The job started |
|
The job was stopped by a call to |
|
The job completed successfully |
Program Attribute Values
Table 150-85 lists program attribute values.
Note:
See the "CREATE_PROGRAM Procedure" for more complete descriptions of the attributes in this table.
Table 150-85 Program Attribute Values
Name | Description |
---|---|
|
An optional comment. This can describe what the program does or give usage details. |
|
If |
|
The number of arguments required by the stored procedure or other executable that the program invokes |
|
The action that the program performs, indicated by the |
|
The type of program. This must be one of these supported program types: ' |
Schedule Attribute Values
Table 150-86 lists schedule attribute values.
Note:
See "CREATE_SCHEDULE Procedure"
for more complete descriptions of the attributes in this table.
Table 150-86 Schedule Attribute Values
Name | Description |
---|---|
|
An optional comment. |
|
The cutoff date and time after which the schedule does not specify any dates. |
|
This attribute takes two values: the |
|
An attribute specifying how often the schedule should repeat, using the calendaring syntax. See "Calendaring Syntax" for more information. |
|
The start or reference date and time used by the calendaring syntax. |
File Watcher Attribute Values
Table 150-87 lists file watcher attribute values.
Table 150-87 File Watcher Attribute Values
Parameter | Description |
---|---|
|
Remote host name or IP address where the file is expected to arrive. If |
|
Directory in which the file is expected to arrive. The single wildcard '?' at the beginning of the path denotes the Oracle home path. For example, '?/rdbms/log' denotes the rdbms/log subdirectory of the Oracle home directory. |
|
Name of the file being looked for. Two wildcards are permitted anywhere in the file name: '?' denotes any single character, and '*' denotes zero or more characters. This attribute cannot be |
|
Name of a valid credential object. The file watcher uses the credential to authenticate itself with the host operating system to access the watched-for file. The file watcher owner must have the |
|
Minimum file size in bytes before the file watcher considers the file found. Default is 0. |
|
Minimum time interval that the file must remain unchanged before the file watcher considers the file found. If |
|
Optional comment. |
Job Class Attribute Values
Table 150-88 lists job class attribute values.
Note:
See the "CREATE_JOB_CLASS Procedure" for more complete descriptions of the attributes in this table.
Table 150-88 Job Class Attribute Values
Name | Description |
---|---|
|
An optional comment about the class. |
|
This attribute controls the number of days that job log entries for jobs in this class are retained. It helps prevent the job log from growing indiscriminately. The range of valid values is 0 through 1000000. If set to 0, no history is kept. If |
|
This attribute specifies how much information is logged. The valid values are:
|
|
The resource consumer group that a class is associated with. All jobs in the class run under this resource consumer group. See Oracle Database Administrator's Guide for a description of resource consumer groups and the Database Resource Manager. |
|
The database service that the jobs in the job class have affinity to. If both the |
Window Attribute Values
Table 150-89 lists window attribute values.
Note:
See the "CREATE_WINDOW Procedure" for more complete descriptions of the attributes in this table.
Table 150-89 Window Attribute Values
Name | Description |
---|---|
|
An optional comment about the window. |
|
The duration of the window. |
|
The date after which the window no longer opens. If this is set, |
|
An attribute specifying how often the schedule should repeat, using the calendaring syntax. PL/SQL date functions are not allowed. If this is set, |
|
The resource plan to be associated with a window. When the window opens, the system switches to this resource plan. When the window closes, the original resource plan is restored. If a resource plan has been made active with the Only one resource plan can be associated with a window. It may be |
|
The name of a schedule to use with this window. If this is set, |
|
The next date and time on which this window is scheduled to open. If this is set, |
|
The priority of the window. Must be either ' |
Chain Attribute Values
Table 150-90 lists chain attribute values.
Note:
See the "CREATE_CHAIN Procedure" for more complete descriptions of the attributes in this table.
Table 150-90 Chain Attribute Values
Name | Description |
---|---|
|
An optional comment describing the purpose of the chain. |
|
If not This attribute should only to be used when chain rules use SQL syntax and the rule conditions contain elements that are not under the control of the Scheduler, because the extra interval is CPU intensive. For most chains, the normal evaluation times are sufficient. |
|
In the normal case, no rule set should be passed in. The Scheduler automatically creates a rule set and associated empty evaluation context. You then use Advanced users can create a rule set that describes their chain dependencies and pass it in here. This allows greater flexibility in defining rules. For example, conditions can refer to external variables, and tables can be exposed through the evaluation context. If you pass in a rule set, you must ensure that it is in the format of a chain rule set. (For example, all steps must be listed as variables in the evaluation context). If no rule set is passed in, the rule set created is of the form |
Database Destination Attribute Values
Table 150-91 lists database destination attribute values.
Note:
See the "CREATE_DATABASE_DESTINATION Procedure" for more complete descriptions of the attributes in this table.
Table 150-91 Database Destination Attribute Values
Name | Description |
---|---|
|
The name of the external destination (also known as agent destination) that is used to connect to the remote database. You can obtain valid external destination names from the view |
|
The TNS connect descriptor that identifies the remote database to connect to, or the net service name (alias) in tnsnames.ora that resolves to the connect descriptor. Note: This corresponds to the |
|
If |
|
An optional comment about the database destination. |
External Destination Attribute Values
Table 150-92 lists external destination attribute values.
Note:
External destinations are created only implicitly by registering a remote Scheduler agent with the local database.
Table 150-92 External Destination Attribute Values
Name | Description |
---|---|
|
( |
|
( |
|
( |
|
If |
|
An optional comment about the external destination. |
Group Attribute Values
Table 150-93 lists group attribute values.
Note:
See the "CREATE_GROUP Procedure" for more complete descriptions of the attributes in this table.
Table 150-93 Group Attribute Values
Name | Description |
---|---|
|
( |
|
Comma-separated list of members. Replaces the existing list of members. To add one or more members to the existing list, use Note: this attribute corresponds to the |
|
If |
|
An optional comment about the group. |
|
( |
Credential Attribute Values
Table 150-94 lists credential attribute values.
Note:
Credential attribute values for the SET_ATTRIBUTE
and GET_ATTRIBUTE
procedures are deprecated with Oracle Database Release 12c Release 1 (12.1). While these attribute values remain available in this package, for reasons of backward compatibility, Oracle recommends using the alternative enhanced functionality provided in the DBMS_CREDENTIAL package, specifically the attribute parameter in the UPDATE_CREDENTIAL Procedure.
Table 150-94 Credential Attribute Values
Name | Description |
---|---|
|
The user name for logging into to the host operating system or remote Oracle database. Maximum length is 64. |
|
The password for the user name. Maximum length is 128. |
|
A description of the credential. Maximum length is 240. |
|
For a Windows remote executable target, this is the domain that the specified user belongs to. Maximum length is 64. |
|
The value of the Valid values are: |
Resource Attribute Values
Table 150-95 lists resource attribute values.
Table 150-95 Resource Attribute Values
Name | Description |
---|---|
|
The name of the resource |
|
The number of units of this resource that the job or program uses. |
|
The status of the resource.
|
|
Level of the constraint: For incompatibilities, for |
|
Descriptive comment about the resource. |
150.6.68 SET_ATTRIBUTE_NULL Procedure
This procedure sets an attribute of an object to NULL
.
The attributes that can be set depend on the object being altered. If the object is enabled, it is disabled before being altered and reenabled afterward. If the object cannot be reenabled, an error is generated and the object is left in a disabled state.
Syntax
DBMS_SCHEDULER.SET_ATTRIBUTE_NULL ( name IN VARCHAR2, attribute IN VARCHAR2);
Parameters
Table 150-96 SET_ATTRIBUTE_NULL Procedure Parameters
Parameter | Description |
---|---|
|
The name of the object |
|
The attribute being changed |
Usage Notes
To run SET_ATTRIBUTE_NULL
for a window, group of type WINDOW
, or job class, you must have the MANAGE
SCHEDULER
privilege. Otherwise, you must be the owner of the object being altered or have ALTER
privileges on that object or have the CREATE
ANY
JOB
privilege.
150.6.69 SET_JOB_ANYDATA_VALUE Procedure
This procedure sets the value for an argument of the associated program for a job, encapsulated in an AnyData
object.
It overrides any default value set for the program argument. NULL
is a valid assignment for a program argument.
The argument can be specified by position or by name. You can specify by name only when:
-
The job points to a saved program object
-
The argument was assigned a name with the DEFINE_ANYDATA_ARGUMENT Procedure
Scheduler does no type checking of the argument at any time.
SET_JOB_ANYDATA_VALUE
is overloaded.
Syntax
Sets a program argument by its position.
DBMS_SCHEDULER.SET_JOB_ANYDATA_VALUE ( job_name IN VARCHAR2, argument_position IN PLS_INTEGER, argument_value IN SYS.ANYDATA);
Sets a program argument by its name.
DBMS_SCHEDULER.SET_JOB_ANYDATA_VALUE ( job_name IN VARCHAR2, argument_name IN VARCHAR2, argument_value IN SYS.ANYDATA);
Parameters
Table 150-97 SET_JOB_ANYDATA_VALUE Procedure Parameters
Parameter | Description |
---|---|
|
The name of the job to be altered |
|
The name of the program argument being set |
|
The position of the program argument being set |
|
The new value to be assigned to the program argument, encapsulated in an |
Usage Notes
SET_JOB_ANYDATA_VALUE
requires that you own the job or have ALTER
privileges on that job. You can also set a job argument value if you have the CREATE
ANY
JOB
privilege.
SET_JOB_ANYDATA_VALUE
does not apply to lightweight jobs because lightweight jobs cannot take AnyData
arguments.
150.6.70 SET_JOB_ARGUMENT_VALUE Procedure
This procedure sets the value of an argument for a job.
It overrides any default value set for the corresponding program or stored procedure argument. The argument can be specified by position or by name. You can specify by name only when:
-
The job points to a saved program object
-
The argument was assigned a name with the DEFINE_PROGRAM_ARGUMENT Procedure or the DEFINE_METADATA_ARGUMENT Procedure
Scheduler does no type checking of the argument at any time.
SET_JOB_ARGUMENT_VALUE
is overloaded.
Syntax
Sets an argument value by position:
DBMS_SCHEDULER.SET_JOB_ARGUMENT_VALUE ( job_name IN VARCHAR2, argument_position IN PLS_INTEGER, argument_value IN VARCHAR2);
Sets an argument value by name:
DBMS_SCHEDULER.SET_JOB_ARGUMENT_VALUE ( job_name IN VARCHAR2, argument_name IN VARCHAR2, argument_value IN VARCHAR2);
Parameters
Table 150-98 SET_JOB_ARGUMENT_VALUE Procedure Parameters
Parameter | Description |
---|---|
|
The name of the job to be altered |
|
The name of the program argument being set |
|
The position of the program argument being set |
|
The new value to be set for the program argument. To set a non- |
Usage Notes
SET_JOB_ARGUMENT_VALUE
requires that you be the owner of the job or have ALTER
privileges on that job. You can also set a job argument value if you have the CREATE
ANY
JOB
privilege.
SET_JOB_ARGUMENT_VALUE
only supports arguments of SQL type. Therefore, argument values that are not of SQL type, such as booleans, are not supported as program or job arguments.
SET_JOB_ARGUMENT_VALUE
can be used to set arguments of lightweight jobs but only if the argument is of type VARCHAR2
.
150.6.71 SET_JOB_ATTRIBUTES Procedure
This procedure changes an attribute of a job.
Syntax
DBMS_SCHEDULER.SET_JOB_ATTRIBUTES ( jobattr_array IN JOBATTR_ARRAY, commit_semantics IN VARCHAR2 DEFAULT 'STOP_ON_FIRST_ERROR');
Parameters
Table 150-99 SET_JOB_ATTRIBUTES Procedure Parameters
Parameter | Description |
---|---|
|
The array of job attribute changes. |
|
The commit semantics. The following types are supported:
|
Usage Notes
Calling SET_ATTRIBUTE
on an enabled job disables the job, changes the attribute value, and reenables the job. SET_JOB_ATTRIBUTES
changes the attribute values in the context of a single transaction.
150.6.72 SET_RESOURCE_CONSTRAINT Procedure
This procedure allows users to specify the resources used by jobs.
Syntax
DBMS_SCHEDULER.SET_RESOURCE_CONSTRAINT ( object_name IN VARCHAR2, resource_name IN VARCHAR2, units IN NUMBER DEFAULT 1);
Parameters
Table 150-100 SET_RESOURCE_CONSTRAINT Procedure Parameters
Parameter | Description |
---|---|
|
The name of a program or a job, or a comma separated list of these objects. |
|
The name of the resource. |
|
The number of units of this resource that the job or program uses. |
Usages Notes
object_name
can be the name or comma-separated list of names of either programs or jobs. This creates a constraint on the named resource for these programs or jobs.
units
specifies the number of units of the resource that the program or job can use. If units
is set to 0,
then the program or job does not use this resource anymore, and the resulting constraint is deleted. Setting units
to 0
on a resource with no previous constraint results in an error.
When multiple constraints are defined on the same resource, the object types must match. When one or more existing constraints for a resource are based on jobs and a new constraint is added for the same resource that is based on a program (or vice versa) an error will be raised.
150.6.73 SET_SCHEDULER_ATTRIBUTE Procedure
This procedure sets the value of a Scheduler attribute. This takes effect immediately but the resulting changes may not be seen immediately, depending on the attribute affected.
Table 150-101 provides short attribute descriptions for the SET_SCHEDULER_ATTRIBUTE
procedure. For complete descriptions, see section "Setting Scheduler Preferences" in Oracle Database Administrator's Guide.
Syntax
DBMS_SCHEDULER.SET_SCHEDULER_ATTRIBUTE ( attribute IN VARCHAR2, value IN VARCHAR2);
Parameters
Table 150-101 SET_SCHEDULER_ATTRIBUTE Procedure Parameters
Parameter | Description |
---|---|
|
The name of the Scheduler attribute. Possible values are:
|
|
The new value of the attribute |
Usage Notes
To run SET_SCHEDULER_ATTRIBUTE
, you must have the MANAGE
SCHEDULER
privilege.
See Also:
Oracle Database Administrator's Guide for more detailed descriptions of Scheduler attributes
150.6.74 STOP_JOB Procedure
This procedure stops currently running jobs or all jobs in a job class.
After stopping the job, the state of a one-time job is set to STOPPED
, whereas the state of a repeating job is set to SCHEDULED
or COMPLETED
, depending on whether the next run of the job is scheduled.
If a job pointing to a chain is stopped, all running steps of the running chain are stopped.
If a job has multiple destinations, the database attempts to stop the job at all destinations.
For external jobs, STOP_JOB
stops only the external process that was directly started by the job action. It does not stop child processes of external jobs.
For in-memory full jobs in an Oracle Real Application Clusters environment, STOP_JOB
uses the instance_id
attribute of the job definition to determine in which instance (or all of them if the attribute is left null) to stop the in-memory full job. (In-memory full jobs are kept cached in memory, and as such are limited to the instance currently caching them. Because of this, the same job_name
can in some conditions be used for different jobs on different instances.)
Syntax
DBMS_SCHEDULER.STOP_JOB ( job_name IN VARCHAR2 force IN BOOLEAN DEFAULT FALSE commit_semantics IN VARCHAR2 DEFAULT 'STOP_ON_FIRST_ERROR');
Parameters
Table 150-102 STOP_JOB Procedure Parameters
Parameter | Description |
---|---|
|
Name of a job to stop. Can be a comma-separate list of jobs, where each entry can be one of the following:
If you specify a job class, all jobs that belong to that job class are stopped. If you specify a job that was created with a destination group as its |
|
If If Use of the |
|
The commit semantics. The following two types are supported:
|
Usage Notes
STOP_JOB
without the force
option requires that you be the owner of the job or have ALTER
privileges on that job. You can also stop a job if you have the CREATE
ANY
JOB
or MANAGE
SCHEDULER
privilege.
STOP_JOB
with the force
option requires that you have the MANAGE
SCHEDULER
privilege.
Example
The following is an example of using STOP_JOB
.
BEGIN DBMS_SCHEDULER.STOP_JOB('DSS.ETLJOB, 984, 1223, SYS.ETL_JOBCLASS'); END;