Oracle FAQ | Your Portal to the Oracle Knowledge Grid |
![]() |
![]() |
Home -> Community -> Mailing Lists -> Oracle-L -> RE: Job to run first Wednesday
What an interesting question.
Alright, DBMS_JOB needs a function which returns the date/time on which the job will next run. Part of your function is to take consider the next 31 days (in case the current run of the job is somewhere random in the month and not on the first Wednesday of the current month) and identify the very next Wednesday, that happens to occur in the first 7 days of the month.
With that in mind:
select run_date
from (select to_char(sysdate + rownum, 'dd-Mon-yyyy') run_date, to_char(sysdate + rownum, 'w') week_of_month, to_char(sysdate + rownum, 'd') day_of_week from all_objects where rownum <= 31) where week_of_month = 1 and day_of_week = 4;
The inline makes use of a table/view that more or less is assumed to contain at least 31 objects in order to generate an offset to represent each day for the next month or so, which is added to the current sysdate. The inline view returns the date, week of month, and day of week for the upcoming 31 days (but necessarily excludes today if today happens to be the first Wed of this month, otherwise your job will always identify today as being the next scheduled run time, and never manage to find next month's first Wed).
The enclosing query then takes all the date information for the upcoming week, and limits it to the single record that occurs within the first week of the month, and is also the fourth day of the week (which is Wed.)
You may need to trunc() the run_date and do some other arithmatic to nail down a specific time of day for that job to run.
Go have fun.
...Rudy
-----Original Message-----
From: Josh Collier [mailto:Josh.Collier_at_Banfield.net]
Sent: Tuesday, July 22, 2003 3:14 PM
To: Multiple recipients of list ORACLE-L
Subject: Job to run first Wednesday
Greetings,
How can I set the interval in my dbms job to have it run on the first Wednesday of every month? Is this even possible? I have been trying to noodle it thru for a week to no avail.
tia,
Josh
--
Please see the official ORACLE-L FAQ: http://www.orafaq.net
--
Author: Josh Collier
INET: Josh.Collier_at_Banfield.net
Fat City Network Services -- 858-538-5051 http://www.fatcity.com San Diego, California -- Mailing list and web hosting services ---------------------------------------------------------------------To REMOVE yourself from this mailing list, send an E-Mail message to: ListGuru_at_fatcity.com (note EXACT spelling of 'ListGuru') and in the message BODY, include a line containing: UNSUB ORACLE-L (or the name of mailing list you want to be removed from). You may Received on Tue Jul 22 2003 - 13:53:10 CDT
![]() |
![]() |