Call now: 252-767-6166  
Oracle Training Oracle Support Development Oracle Apps

 
 Home
 E-mail Us
 Oracle Articles
New Oracle Articles


 Oracle Training
 Oracle Tips

 Oracle Forum
 Class Catalog


 Remote DBA
 Oracle Tuning
 Emergency 911
 RAC Support
 Apps Support
 Analysis
 Design
 Implementation
 Oracle Support


 SQL Tuning
 Security

 Oracle UNIX
 Oracle Linux
 Monitoring
 Remote s
upport
 Remote plans
 Remote
services
 Application Server

 Applications
 Oracle Forms
 Oracle Portal
 App Upgrades
 SQL Server
 Oracle Concepts
 Software Support

 Remote S
upport  
 Development  

 Implementation


 Consulting Staff
 Consulting Prices
 Help Wanted!

 


 Oracle Posters
 Oracle Books

 Oracle Scripts
 Ion
 Excel-DB  

Don Burleson Blog 


 

 

 


 

 

 
 


Make a list of public holidays dates

Expert Oracle Database Tips by Donald BurlesonSeptember 3, 2015

Question:  I need to write a SQL that filters out for a list of public holidays and I need to know how to generate a list of public holidays into an Oracle table.  Where does Oracle keep the function to create a list of dates for public holidays?

Answer: As noted in  the great book Oracle Job Scheduling,  you can generate a list of dates very easily.  David Aldridge creates a list_of_dates PL/SQL function for this:

create or replace type timestamp_table_type
is
table of timestamp;
/

create or replace function
 list_of_dates (
   calendar_string varchar2,
   start_date      TIMESTAMP WITH TIME ZONE,
   stop_date       TIMESTAMP WITH TIME ZONE)
return
  timestamp_table_type
pipelined
is
  l_return_date_after TIMESTAMP WITH TIME ZONE := start_date - interval '1' second;
  l_next_run_date     TIMESTAMP WITH TIME ZONE;
begin
  loop
    DBMS_SCHEDULER.EVALUATE_CALENDAR_STRING(  
      calendar_string   => list_of_dates.calendar_string,
      start_date        => list_of_dates.start_date,
      return_date_after => l_return_date_after,
      next_run_date     => l_next_run_date);

      exit when list_of_dates.l_next_run_date > coalesce(list_of_dates.stop_date,date '9999-12-31');

      pipe row (list_of_dates.l_next_run_date);

      list_of_dates.l_return_date_after    := list_of_dates.l_next_run_date;

 end loop;
end;
/

Using this list_of_dates function you can generate a list of complex date from dbms_scheduler:

-- ******************************************
-- generate list of weekday dates

-- ******************************************
create table

   weekdays
as
select *
from   table(
list_of_dates(
'WEEKDAYS;EXCLUDE=PUBLIC_HOLIDAYS',
sysdate    ,
null));

-- ********************************************
-- generate list of weekday dates, no holidays

-- ********************************************
create table

   weekdays_no_holidays
as
select *
from   table(
list_of_dates(
'WEEKDAYS;EXCLUDE=PUBLIC_HOLIDAYS',
sysdate    ,
null));


-- ********************************************
-- generate list of weekends
-- ********************************************
create table
   weekends
as
select *

from   table(
list_of_dates(
'WEEKENDS',
sysdate    ,
null));

 
Get the Complete
Oracle SQL Tuning Information 

The landmark book "Advanced Oracle SQL Tuning  The Definitive Reference"  is filled with valuable information on Oracle SQL Tuning. This book includes scripts and tools to hypercharge Oracle 11g performance and you can buy it for 30% off directly from the publisher.

 

 

Burleson is the American Team

Note: This Oracle documentation was created as a support and Oracle training reference for use by our DBA performance tuning consulting professionals.  Feel free to ask questions on our Oracle forum.

Verify experience! Anyone considering using the services of an Oracle support expert should independently investigate their credentials and experience, and not rely on advertisements and self-proclaimed expertise. All legitimate Oracle experts publish their Oracle qualifications.

Errata?  Oracle technology is changing and we strive to update our BC Oracle support information.  If you find an error or have a suggestion for improving our content, we would appreciate your feedback.  Just  e-mail:  

and include the URL for the page.


                    









Burleson Consulting

The Oracle of Database Support

Oracle Performance Tuning

Remote DBA Services


 

Copyright © 1996 -  2017

All rights reserved by Burleson

Oracle ® is the registered trademark of Oracle Corporation.

Remote Emergency Support provided by Conversational

 

 

��  
 
 
Oracle Training at Sea
 
 
 
 
oracle dba poster
 

 
Follow us on Twitter 
 
Oracle performance tuning software 
 
Oracle Linux poster