Concurrent request scheduling from Backend
It’s quite an interesting way that’s used to implement concurrent request schedules in Oracle Applications. In this post I’ll describe how “Periodic” and “On Specific Day” type of schedules are stored in the Database and if you will be patient enough to read all the story, I’ll give you a query that can be used to report all the request schedules in the environment.
I’ll pay attention to the
repeating schedules only as requests submitted for one-time execution are not
too interesting, basically, they use the fnd_concurrent_requests.requested_start_date field to store the time the request has
to be executed. This field is used in repeating schedules to specify the time
of next execution.
There are just 2 normal
types of repeating schedules.
1. Periodic - the request is submitted for execution in pre-defined
intervals of specified number of months, weeks, days, hours or minutes.
Defining a 'periodic'
schedule
2. On Specific Days - user can choose exact dates of month
or days of week when the request will be executed. There’s an option to
schedule requests for the last day of months too.
Definig a 'on Specific
Days' schedule
There’s also a 3rd option
- Advanced - this is a special option that implements
possibility to run requests based on schedules, that depend on different
financial calendars and financial periods. This kind of scheduling is rarely
used as it’s available in few Applications products only, e.g. GL. These
schedules are managed by Scheduler/Prereleaser Concurrent Manager.
There are 2 tables
invoved in storing the information about schedules: fnd_concurrent_requests that stores all basic information about
concurrent requests including the next time the request is scheduled for,
and fnd_conc_release_classes that stores information about the
schedules. Both tables can be joined by release_class_id.
The fields we are
interested in are:
·
fnd_conc_release_classes.CLASS_TYPE - contains value ‘P’ for “Periodic”
schedules, “S” - for “on Specific Days” schedules and “X” - for advanced
schedules.
·
fnd_conc_release_classes.DATE1 - start date of the schedule (“Start at”
field in the form)
·
fnd_conc_release_classes.DATE2 - end date of the schedule (“End at”
field in the form). This information is doubled also in fnd_concurrent_requests.resubmit_end_date.
·
fnd_conc_release_classes.CLASS_INFO - this is the most interesting field as
it contains all the information needed for rescheduling. The format of the
field depends on the type of schedule.
“PERIODIC” schedule
In case of Periodic schedule fnd_conc_release_classes.CLASS_INFO field contains values like 2:D:S or X:Y:Z where:
·
X - number of
months/weeks/days/hours/minutes the request has to be rescheduled from prior
run.</li>
·
Y - contains a single letter representing
units
o M - months;
o D - days;
o H - hours;
o N - minutes;
o (there is no representation of “weeks” option.
If you specify interval in weeks, it’s automatically calculated and stored in “days”).
·
Z - contains a single letter to represent
if the rescheduling has to be done from start or from completion of the prior
run
o S - from the start of the prior run;
o C - from the completion of the prior run.
Some samples:
·
30:N:S - Repeat every 30 minutes from the start of the prior run
·
5:N:C - Repeat every 5 minutes from the completion of the prior
run
·
12:H:S - Repeat every 12 hours from the start of the prior run
It’s interesting that
information about intervals of periodic schedules is duplicated in fnd_concurrent_requests table fields RESUBMIT_INTERVAL, RESUBMIT_INTERVAL_TYPE_CODE and RESUBMIT_INTERVAL_UNIT_CODE. I haven’t yet found why’s that so.
“ON SPECIFIC DAY”
schedule
In case of on
Specific Day schedule fnd_conc_release_classes.CLASS_INFO field contains values like 000010000000000000000000000000010000000 - a 39 character value consisting
of 0 and 1. The idea is that the placement
of 1-s represent the options selected through form:
·
1 at places 1 to 31 - represent dates, when request has to
be run, eg, if the 10th character is “1” - the request is scheduled to run on
10th day of each month;
·
1 at the 32nd position - specifies that the request has to
be run at the last day of each month;
·
1 at places 33 to 39 - specifies days of week (Sunday -
Saturday)the request has to be run. if the 33rd character is “1” - the request
is scheduled to run each Sunday, if 34th - on Monday and so on.
Some samples:
·
000000000000000000000000000000000000001 - Days of week: Sa
·
111111111000000000000000000000000111110 - Dates: 1 2 3 4 5 6 7 8 9. Days of
week: Mo Tu We Th Fr
·
000000000000000000000000000000010000000 - Last day of month
Reporting all schedules
Using the information
given above I wrote a “small” query to provide a report like this:
Reporting all schedules
The query was tested in
Oracle Applications versions 11.5.9, 11.5.10.1, 12.0.1 and 12.0.4 so there’s a
good chance it will work on others as well. The performance of the query was
OK. but I have to say - test/analyze it before running in productio.
select r.request_id,
p.user_concurrent_program_name ||
case
when p.user_concurrent_program_name
= 'Report
Set' then
(select ' - ' ||
s.user_request_set_name
from fnd_request_sets_tl s
where s.application_id =
r.argument1
and s.request_set_id =
r.argument2
and language =
'US')
when p.user_concurrent_program_name
= 'Check
Periodic Alert' then
(select ' - ' ||
a.alert_name
from alr_alerts a
where a.application_id =
r.argument1
and a.alert_id = r.argument2
and language =
'US')
end concurrent_program_name,
case
when p.user_concurrent_program_name
!= 'Report
Set' and
p.user_concurrent_program_name !=
'Check
Periodic Alert' then
r.argument_text
end argument_text,
r.requested_start_date next_run,
r.hold_flag on_hold,
decode(c.class_type,
'P',
'Periodic',
'S',
'On
Specific Days',
'X',
'Advanced',
c.class_type) schedule_type,
case
when c.class_type =
'P' then
'Repeat every ' ||
substr(c.class_info, 1, instr(c.class_info,
':') -
1) ||
decode(substr(c.class_info, instr(c.class_info,
':', 1, 1) +
1, 1),
'N',
'
minutes',
'M',
' months',
'H',
' hours',
'D',
' days') ||
decode(substr(c.class_info, instr(c.class_info,
':', 1, 2) +
1, 1),
'S',
' from
the start of the prior run',
'C',
' from
the completion of the prior run')
when c.class_type =
'S' then
nvl2(dates.dates, 'Dates: ' ||
dates.dates || '. ', null) ||
decode(substr(c.class_info, 32, 1), '1', 'Last day
of month ') ||
decode(sign(to_number(substr(c.class_info,
33))),
'1',
'Days of
week: ' ||
decode(substr(c.class_info,
33, 1), '1', 'Su ') ||
decode(substr(c.class_info,
34, 1), '1', 'Mo ') ||
decode(substr(c.class_info,
35, 1), '1', 'Tu ') ||
decode(substr(c.class_info,
36, 1), '1', 'We ') ||
decode(substr(c.class_info,
37, 1), '1', 'Th ') ||
decode(substr(c.class_info,
38, 1), '1', 'Fr ') ||
decode(substr(c.class_info,
39, 1), '1', 'Sa '))
end schedule,
c.date1 start_date,
c.date2 end_date,
c.class_info
from fnd_concurrent_requests r,
fnd_conc_release_classes c,
fnd_concurrent_programs_tl p,
(SELECT release_class_id,
substr(max(SYS_CONNECT_BY_PATH(s,
' ')), 2) dates
FROM (select release_class_id,
rank() over(partition by release_class_id
order by s) a,
s
from (select c.class_info,
l,
c.release_class_id,
decode(substr(c.class_info,
l, 1),
'1',
to_char(l))
s
from (select
level l from dual connect by level <=
31),
fnd_conc_release_classes
c
where c.class_type
= 'S')
where s is not
null)
CONNECT BY PRIOR
(a || release_class_id)
= (a - 1) || release_class_id
START WITH a = 1
group by release_class_id)
dates
where r.phase_code = 'P'
and c.application_id = r.release_class_app_id
and c.release_class_id =
r.release_class_id
and nvl(c.date2, sysdate +
1) >
sysdate
and c.class_type is not
null
and p.concurrent_program_id = r.concurrent_program_id
and p.application_id = r.program_application_id
and p.language = 'US'
and dates.release_class_id(+) =
r.release_class_id
order by on_hold, next_run;
I know there are some
interesting lines in this query that might need some explanation, but as that
is not directly connected to the topic of this post I’ll provide explanation in
comments if you will ask for it.



Comments
Post a Comment