PL/SQL Packages and Types Reference 10g Release 1 (10.1) Part Number B10802-01 |
|
|
View PDF |
The DBMS_SCHEDULER
package provides a collection of scheduling functions and procedures that are callable from any PL/SQL program.
See Also:
Oracle Database Administrator's Guide for more information regarding how to use |
This chapter contains the following topics:
The following rules apply when using the DBMS_SCHEDULER
package:
SYS
can do anything in SYS
schema.DBMS_SCHEDULER.STOP_JOB ('job1, job2, job3, sys.jobclass1, sys.jobclass2, sys.jobclass3');
If job3
could not be stopped, then job1
and job2
will be stopped, but the jobs in jobclass1
, jobclass2
, and jobclass3
will not be stopped.This procedure adds one or more windows to an existing window group.
DBMS_SCHEDULER.ADD_WINDOW_GROUP_MEMBER ( group_name IN VARCHAR2, window_list IN VARCHAR2);
Parameter | Description |
---|---|
|
The name of the window group. |
|
The name of the window or windows. |
If an already open window is added to a window group, the Scheduler will not pick up jobs that point to this window group until the next window in the window group opens.
Adding a window to a group requires the MANAGE
SCHEDULER
privilege.
Note that a window group cannot be a member of another window group.
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 will switch the resource plan to the one that was in effect outside the window or in the case of overlapping windows to another window.
DBMS_SCHEDULER.CLOSE_WINDOW ( window_name IN VARCHAR2);
Parameter | Description |
---|---|
|
The name of the window. |
If you try to close a window that does not exist or is not open, an error is generated.
A job that is running will not stop when the window it is running in closes unless the attribute stop_on_close
was set to TRUE
for the job. However, the resources allocated to the job may change because the resource plan may change.
When a running job has a window group as its schedule, the job will not be stopped when its window is closed if another window that is also a member of the same window group then becomes active. This is the case even if the job has the attribute stop_on_close
set to TRUE
.
Closing a window requires the MANAGE
SCHEDULER
privilege.
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.
DBMS_SCHEDULER.COPY_JOB ( old_job IN VARCHAR2, new_job IN VARCHAR2);
Parameter | Description |
---|---|
|
The name of the existing job. |
|
The name of the new job. |
This procedure creates a job.
The procedure is overloaded. The different functionality of each form of syntax is presented along with the syntax declaration.
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);
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);
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);
Creates a job using a named schedule object and an inlined program or 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);
Parameter | Description |
---|---|
|
This attribute specifies the name of the job and uniquely identifies the job. The name has to be unique in the SQL namespace. For example, a job cannot have the same name as a table in a schema. If |
|
This attribute specifies the type of job that you are creating. If it is not specified, an error is generated. The three supported values are: This specifies that the job is an anonymous PL/SQL block. Job or program arguments are not supported when the job or program type is This specifies that the job is an external PL/SQL procedure. By reusing PL/SQL's External Procedure feature, this can also be a Java stored procedure or an external C routine. This specifies that the job is a job external to the database. External jobs are anything that can be executed from the operating system's command line.
|
|
This attribute specifies the action of the job. The following actions are possible: For a PL/SQL block, the action is to execute PL/SQL code. These blocks must end with a semi-colon. For example, For a stored procedure, the action is the name of the stored procedure. You have to specify the schema if the procedure resides in another schema than the job. PL/SQL functions or procedures with For an executable, the action is the name of the external executable, including the full path name and any command-line arguments. If |
|
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. |
|
This attribute specifies the first date 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 will execute on an exact time because the system may be overloaded and thus resources unavailable. |
|
This attribute specifies how often the job should repeat. 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. |
|
This attribute specifies the date after which the job will expire and will no longer be executed. When If no value for The value for |
|
This attribute specifies the job class that the job belongs to. If no job class is specified, then the job is assigned to the default class. Note that the owner of a job must have |
|
This attribute specifies a comment about the job. By default, this attribute is |
|
This attribute specifies whether the job is created enabled or not. The possible settings are |
|
This flag specifies whether the job will be automatically dropped once it has been executed for non-repeating jobs or when its status is changed to If this flag is set to By default, jobs are created with |
Jobs are created disabled by default, thus you must explicitly enable them so they will become active and scheduled.
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.
Associating a job with a particular class or program requires EXECUTE
privileges for that class.
This procedure creates a job class. Job classes are created in the SYS
schema.
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 NULL, log_history IN PLS_INTEGER DEFAULT NULL, comments IN VARCHAR2 DEFAULT NULL);
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.
This procedure creates a program.
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);
To create a program in his own schema, a user needs 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 field is set to TRUE
). It cannot be executed by a job until it is enabled.
For other users to use your programs, they must have EXECUTE
privileges, therefore once a program has been created, you have to grant EXECUTE
privilege on it.
This procedure creates a schedule.
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);
Parameter | Description |
---|---|
|
This attribute specifies a unique identifier for the schedule. The name has to be unique in the SQL namespace. For example, a schedule cannot have the same name as a table i a schema. If no name is specified, then an error occurs. |
|
This attribute specifies the first date on which this schedule becomes valid. For a repeating schedule, the value for If |
|
This attribute specifies how often the schedule should repeat. It is expressed using a calendar expression. See Table 83-9 for further information. PL/SQL expressions are not allowed as repeat intervals for named schedules. |
|
The date 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 |
The calendaring syntax is as follows:
repeat_interval = frequency_clause [";" interval_clause] [";" bymonth_clause] [";" byweekno_clause] [";" byyearday_clause] [";" bymonthday_clause] [";" byday_clause] [";" byhour_clause] [";" byminute_clause] [";" bysecond_clause] frequency_clause = "FREQ" "=" frequency frequency = "YEARLY" | "MONTHLY" | "WEEKLY" | "DAILY" | "HOURLY" | "MINUTELY" | "SECONDLY" interval_clause = "INTERVAL" "=" intervalnum intervalnum = 1 through 99 bymonth_clause = "BYMONTH" "=" monthlist monthlist = monthday ( "," monthday) * 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 = weekday ( "," weeknumber)* week = [minus] weekno minus = "-" weekno = 1 through 53 byyearday_clause = "BYYEARDAY" "=" yearday_list yearday_list = yearday ( "," yearday)* yearday = [minus] yeardaynum yeardaynum = 1 through 366 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" 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
In calendaring syntax, * means 0 or more.
This procedure requires the CREATE
JOB
privilege to create a schedule in one's 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.
When using a calendaring expression, consider the following rules:
BY
clause do not need to be ordered.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.
byweekno
clause is only allowed if the frequency is YEARLY
. 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 a BYDAY
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
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, specifying BYMONTHDAY=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
, and bysecond
are not supported.
byday
clause are the days of the week. When the frequency is YEARLY
, or MONTHLY
, you are allowed to specify a positive or negative number in front of each day of the week. In the case of YEARLY
, BYDAY=40MON
, indicates the 40th Monday of the year. In the case of MONTHLY, 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.
start_date
argument. If jobs must follow daylight savings adjustments you must make sure that you specify a region name for the time zone of the start_date
. For example specifying the start_date
time zone as 'US/Eastern
' in New York will make sure that daylight saving adjustments are automatically applied. If instead the time zone of the start_date
is set to an absolute offset, such as '-5:00
', daylight savings adjustments are not followed and your job execution will be off by an hour half of the year.start_date
is NULL
, the scheduler will determine the time zone for the repeat interval as follows:
DEFAULT_TIMEZONE
scheduler attribute. For more information see the SET_SCHEDULER_ATTRIBUTE Procedure.This procedure creates a Scheduler window consisting of a recurring time window and an associated resource plan.
The procedure is overloaded. The different functionality of each form of syntax is presented along with the syntax declaration.
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);
Creating a window requires the MANAGE
SCHEDULER
privilege. Windows always reside in the SYS
schema.
This procedure creates a new window group.
DBMS_SCHEDULER.CREATE_WINDOW_GROUP ( group_name IN VARCHAR2, window_list IN VARCHAR2 DEFAULT NULL, comments IN VARCHAR2 DEFAULT NULL);
Creating a window group requires the MANAGE
SCHEDULER
privilege. Window groups reside in the SYS
schema. Window groups, like windows, are created with access to PUBLIC
, therefore, no privileges are required to access window groups.
A window group cannot contain another window group
This procedure defines a program argument whose value is of a complex type and must be encapsulated within an AnyData
object.
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);
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.
This procedure defines a special metadata argument for the program. You can retrieve specific Scheduler metadata through this argument. You cannot set values for jobs using this argument. Valid metadata attributes are: job_name
, job_owner
, job_start
, window_start
, and window_end
.
DBMS_SCHEDULER.DEFINE_METADATA_ARGUMENT ( program_name IN VARCHAR2, metadata_attribute IN VARCHAR2, argument_position IN PLS_INTEGER, argument_name IN VARCHAR2 DEFAULT NULL);
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.
This procedure defines program arguments. This does not affect whether a program is enabled or not. Defining a program argument can be used to assign a default value or a name to the argument.
This procedure is overloaded. The different functionality of each form of syntax is presented along with the syntax declaration.
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, out_argument IN BOOLEAN DEFAULT FALSE);
Defines a program argument without a default value:
PROCEDURE 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);
All program arguments from 1 to the number_of_arguments
value must be defined before a program can be enabled.
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.
This procedure disables a program, job, window, or window group.
DBMS_SCHEDULER.DISABLE ( name IN VARCHAR2, force IN BOOLEAN DEFAULT FALSE);
Disabling an object that is already disabled does not generate an error. Because the DISABLE
procedure is used for several Scheduler objects, when disabling windows and window groups, they must be preceded by SYS
.
The purpose of the force
option is to point out dependencies. No dependent objects are altered.
To run DISABLE
for a window or window group, you must have the MANAGE
SCHEDULER
privilege. Otherwise, you must be the owner of the object being disabled or have ALTER
privileges on that object or have the CREATE
ANY
JOB
privilege.
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.
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 be unreferenced 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
Any argument that pertains to the program will not be affected when the program is disabled.
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 will occur.
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 re-enabled.
When the window is disabled, those jobs that have the window as their schedule will not be disabled.
When a window group is disabled, jobs, other than a running job, that has the window group as its schedule will not run even if the member windows open. However, if the job had one of the window group members as its schedule, it would still run.
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
:
This procedure drops a job or all jobs in a job class. It results in the job being removed from the job queue, its metadata being removed, and no longer being visible in the *_SCHEDULER_JOBS
views. Therefore, no more runs of the job will be executed. Dropping a job also drops all argument values set for that job.
DBMS_SCHEDULER.DROP_JOB ( job_name IN VARCHAR2, force IN BOOLEAN DEFAULT FALSE);
This procedure drops a job class. Dropping a job class means that all the metadata about the job class is removed from the database.
DBMS_SCHEDULER.DROP_JOB_CLASS ( job_class_name IN VARCHAR2, force IN BOOLEAN DEFAULT FALSE);
Dropping a class requires the MANAGE
SCHEDULER
system privilege.
DROP_JOB
requires that you be the owner of the job or have ALTER
privileges on that job. You can also drop a job if you have the CREATE
ANY
JOB
privilege.
This procedure drops a program. Any arguments that pertain to the program are also dropped when the program is dropped.
DBMS_SCHEDULER.DROP_PROGRAM ( program_name IN VARCHAR2, force IN BOOLEAN DEFAULT FALSE);
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.
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. The different functionality of each form of syntax is presented along with the syntax declaration.
Drops a program argument either by position:
DBMS_SCHEDULER.DROP_PROGRAM_ARGUMENT ( program_name IN VARCHAR2, argument_position IN PLS_INTEGER);
Drops a program argument either by name:
DBMS_SCHEDULER.DROP_PROGRAM_ARGUMENT ( program_name IN VARCHAR2, argument_name IN VARCHAR2);
Dropping 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.
This procedure drops a schedule.
DBMS_SCHEDULER.DROP_SCHEDULE ( schedule_name IN VARCHAR2, force IN BOOLEAN DEFAULT FALSE);
You must be the owner of the schedule being dropped or have ALTER
privileges for the schedule or the CREATE
ANY
JOB
privilege.
This procedure drops a window. All metadata about the window is removed from the database. All references to the window are removed from window groups.
DBMS_SCHEDULER.DROP_WINDOW ( window_name IN VARCHAR2, force IN BOOLEAN DEFAULT FALSE);
Dropping a window requires the MANAGE
SCHEDULER
privilege.
This procedure drops a window group but not the windows that are members of this window group.
DBMS_SCHEDULER.DROP_WINDOW_GROUP ( group_name IN VARCHAR2 force IN BOOLEAN DEFAULT FALSE);
If you want to drop all the windows that are members of this group but not the window group itself, you can use the DROP_WINDOW
procedure and provide name of the window group to the call.
To drop a window group, you must have the MANAGE
SCHEDULER
privilege.
This procedure enables a program, job, window, or window group. When an object is enabled, the enabled flag is set to TRUE
. By default, jobs and programs are created disabled and windows and window groups are created enabled.
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.
DBMS_SCHEDULER.ENABLE ( name IN VARCHAR2);
Because the ENABLE
procedure is used for several Scheduler objects, when enabling windows or window groups, they must be preceded by SYS
.
To run ENABLE
for a window or window group, you must have the MANAGE
SCHEDULER
privilege. Otherwise, you must be the owner of the object being enabled or have ALTER
privileges on that object or have the CREATE
ANY
JOB
privilege.
You can define repeat intervals of jobs, windows or schedules using the Scheduler's calendar syntax. This procedure evaluates the calendar string and tells you what the next execution date of a job or window will be. This is very useful for testing the correct definition of the calendar string without having to actually schedule the job or window.
This procedure can also be used to 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 of this procedure.
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);
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.
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.
DBMS_SCHEDULER.GENERATE_JOB_NAME ( prefix IN VARCHAR2 DEFAULT 'JOB$_') RETURN VARCHAR2;
Parameter | Description |
---|---|
|
The name of the prefix being returned. |
If the prefix is explicitly set to NULL
, the name will be 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 will never return the same job name twice, there is a small chance that the returned name happens to match an already existing database object.
This procedure retrieves the value of an attribute of a Scheduler object. It is overloaded to output values of the following types: VARCHAR2
, TIMESTAMP
WITH
TIMEZONE
, BOOLEAN
, PLS_INTEGER
, and INTERVAL
DAY
TO
SECOND
.
DBMS_SCHEDULER.GET_ATTRIBUTE ( name IN VARCHAR2, attribute IN VARCHAR2, value OUT [VARCHAR2, TIMESTAMP WITH TIMEZONE, PLS_INTEGER, BOOLEAN, INTERVAL DAY TO SECOND]);
Parameter | Description |
---|---|
|
The name of the object. |
|
The attribute being retrieved. |
|
The existing value of the attribute. |
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 a window 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.
This procedure retrieves the value of a Scheduler attribute. The attributes you can retrieve are max_job_slave_processes
, log_history
, and current_open_window
. The Scheduler attribute current_open_window can only be retrieved (it can never be set) and it will contain the name of the currently active window, if any.
DBMS_SCHEDULER.GET_SCHEDULER_ATTRIBUTE ( attribute IN VARCHAR2, value OUT VARCHAR2);
Parameter | Description |
---|---|
|
The name of the Scheduler attribute. |
|
The existing value of the attribute. |
To run GET_SCHEDULER_ATTRIBUTE
, you must have the MANAGE
SCHEDULER
privilege.
This procedure opens a window independent of its schedule. This window will open and the resource plan associated with it, will take 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.
DBMS_SCHEDULER.OPEN_WINDOW ( window_name IN VARCHAR2, duration IN INTERVAL DAY TO SECOND, force IN BOOLEAN DEFAULT FALSE);
If there are jobs running when the window opens, the resources allocated to them might change due to the switch in resource plan.
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 will be as 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.
A window can fail to open if the resource plan has been manually switched using the ALTER
SYSTEM
statement with the force
option.
Opening a window requires the MANAGE
SCHEDULER
privilege for that window.
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 is used to purge additional rows from the job and window log.
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);
The following will completely purge all rows from both the job log and the window log:
DBMS_SCHEDULER.PURGE_LOG();
The following will purge all rows from the window log that are older than 5 days:
DBMS_SCHEDULER.PURGE_LOG(5, 'window_log');
The following will purge 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 are older than 1 day:
DBMS_SCHEDULER>PURGE_LOG(1, 'job_and_window_log', 'sys.jobclass1');
This procedure removes one or more windows from an existing window group.
DBMS_SCHEDULER.REMOVE_WINDOW_GROUP_MEMBER ( group_name IN VARCHAR2, window_list IN VARCHAR2);
Parameter | Description |
---|---|
|
The name of the window group. |
|
The name of the window or windows. |
If any of the windows specified is either invalid, does not exist, or is not a member of the given group, the call fails. Removing a window from a group requires the MANAGE
SCHEDULER
privilege.
Dropping an open window from a window group has no impact on running jobs that has the window as its schedule since the jobs would only be stopped when a window closes.
This procedure resets (clears) the value previously set to an argument for a job.
RESET_JOB_ARGUMENT_VALUE
is overloaded.
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);
Parameter | Description |
---|---|
|
The name of the job being queried. |
|
The position of the program argument being altered. |
|
The name of the program argument being altered. |
If the corresponding program argument has no default value, the job will be 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 set a job argument value if you have the CREATE
ANY
JOB
privilege.
This procedure runs a job immediately.
DBMS_SCHEDULER.RUN_JOB ( job_name IN VARCHAR2, use_current_session IN BOOLEAN DEFAULT TRUE);
A job must be enabled for RUN_JOB
to run. The job can be run in two different modes. One is in the current user session. In this case, the call to RUN_JOB
will block until it has completed the job. Any errors that occur during the execution of the job will be returned as errors to the RUN_JOB
procedure. The other option is to run the job immediately like a regular job. In this case, RUN_JOB
returns immediately and the job will be picked up by the 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 be the owner of the job or have ALTER
privileges on that job. You can also run a job if you have the CREATE
ANY
JOB
privilege.
This procedure changes an attribute of a Scheduler object. It is overloaded to accept values of the following types: VARCHAR2
, TIMESTAMP
WITH
TIMEZONE
, BOOLEAN
, PLS_INTEGER
, and INTERVAL
DAY
TO
SECOND
. To set an attribute to NULL
, the SET_ATTRIBUTE_NULL
procedure should be used. What attributes can be set depends on the object being altered. With the exception of the object name, all object attributes can be changed.
SET_ATTRIBUTE
is overloaded.
DBMS_SCHEDULER.SET_ATTRIBUTE ( name IN VARCHAR2, attribute IN VARCHAR2, value IN [VARCHAR2, TIMESTAMP WITH TIMEZONE, PLS_INTEGER, BOOLEAN, INTERVAL DAY TO SECOND]);
Parameter | Description |
---|---|
|
The name of the object. |
|
See Table 83-34, Table 83-35, Table 83-36, Table 83-37, Table 83-38, and Table 83-38. |
|
The new value being set for the attribute. This cannot be |
If an object is altered and it was in the enabled state, the Scheduler will first disable it, make the change and then re-enable it. If any errors are encountered during the enable process, the object is not re-enabled and an error is generated.
If an object is altered and it was in the disabled, it will remain disabled after it is altered.
To run SET_ATTRIBUTE
for a window, window group, 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.
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 seen in 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 will be 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 will take effect the next time the job runs. Program attributes of a job include program_name
, job_action
, job_type
, and number_of_arguments
. This is also the case for job argument values that have been set.
Granting ALTER
on a job will let 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 will not allow a user to use a PL/SQL expression to specify the schedule for a job.
We recommend you not to 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 several views.
If any currently running jobs use the program that is altered, they will continue to run with the program definition prior to the alter. The job will run with the new program definition the next time the job executes.
If a schedule is altered, the change will not affect running jobs and open windows that use this schedule. The change will only be in effect the next time the jobs runs or the window opens.
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.
When a window is altered, it does not affect an active window. The changes only take effect the next time the window opens.
To change resource plans, you must first set the RESOURCE_MANAGER_PLAN
initialization parameter in the init.ora
file or issue an ALTER SYSTEM SET RESOURCE_MANAGER_PLAN =
my_plan
statement before the window opens.
Table 83-34 lists job attribute values.
Table 83-35 lists program attribute values.
Table 83-36 lists job class attribute values.
Table 83-37 lists window attribute values.
Table 83-38 lists program window group values.
Name | Description |
---|---|
|
An optional comment about the window group. |
Table 83-39 lists schedule attribute values.
This procedure sets an attribute of a Scheduler object to NULL
. What attributes can be set depends on the object being altered. If the object is enabled, it will be disabled before being altered and be reenabled afterward. If the object cannot be re-enabled, an error is generated and the object will be left in a disabled state.
DBMS_SCHEDULER.SET_ATTRIBUTE_NULL ( name IN VARCHAR2, attribute IN VARCHAR2);
Parameter | Description |
---|---|
|
The name of the object. |
|
The attribute being changed. |
To run SET_ATTRIBUTE_NULL
for a window, window group, 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.
This procedure sets a value to an argument of the associated program for a job, encapsulated in an AnyData
object. It overrides any default value set for the program argument. This does not affect whether the job is enabled or not. NULL
is a valid assignment for a program argument. Arguments can be specified by position or by name. No type checking of the argument is done at any time by the Scheduler.
SET_JOB_ANYDATA_VALUE
is overloaded.
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);
SET_JOB_ANYDATA_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.
This procedure sets a value to an argument of the associated program for a job. It overrides any default value set for the program argument. This does not affect whether a job is enabled or not. NULL
is a valid assignment for a program argument. Arguments can be specified by position or by name. No type checking of the argument is done at any time by the Scheduler.
SET_JOB_ARGUMENT_VALUE
is overloaded.
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);
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.
This procedure sets the value of a Scheduler attribute. This takes effect immediately but the resulting changes may not be seen immediately. The attributes you can set are default_timezone, max_job_slave_processes and log history.
DBMS_SCHEDULER.SET_SCHEDULER_ATTRIBUTE ( attribute IN VARCHAR2, value IN VARCHAR2);
To run SET_SCHEDULER_ATTRIBUTE
, you must have the MANAGE
SCHEDULER
privilege.
This procedure stops currently running jobs or all jobs in a job class. Any instance of the job will be stopped. After stopping the job, the state of a one-time job will be set to SUCCEEDED
whereas the state of a repeating job will be set to SCHEDULED
or COMPLETED
depending on whether the next run of the job is scheduled.
DBMS_SCHEDULER.STOP_JOB ( job_name IN VARCHAR2 force IN BOOLEAN DEFAULT FALSE);
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 have the MANAGE
SCHEDULER
privilege.