Last active
August 29, 2015 14:03
-
-
Save fljdin/62ada0513048d3b41b0b to your computer and use it in GitHub Desktop.
Evaluate next french working day from a date and a frequency string
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
-- ----------------------------------- | |
-- FUNCTION: easter_date | |
-- ----------------------------------- | |
CREATE OR REPLACE FUNCTION easter_date(year integer) | |
RETURNS timestamp as $$ | |
DECLARE | |
g integer := year % 19; | |
c integer := (year/100)::int; | |
h integer := ((c - (c/4)::int - ((8*c+13)/25)::int + 19*g + 15) % 30)::int; | |
i integer := h - (h/28)::int * (1 - (h/28)::int * (29/(h + 1))::int * ((21 - g)/11)::int); | |
j integer := (year + (year/4)::int + i + 2 - c + (c/4)::int) % 7; | |
l integer := i - j; | |
m integer := 3 + ((l + 40)/44)::int; | |
d integer := l + 28 - 31 * (m/4)::int; | |
easter varchar(10) := year::text || '-' || m::text || '-' || d::text; | |
BEGIN | |
return easter::timestamp; | |
END; | |
$$ language plpgsql; | |
-- ----------------------------------- | |
-- FUNCTION: get_holidays | |
-- ----------------------------------- | |
CREATE OR REPLACE FUNCTION get_holidays() | |
RETURNS table(holiday date) AS $$ | |
DECLARE | |
year text := extract(year from current_date); | |
next text := (year::int+1)::text; | |
easter1 timestamp := easter_date(year::int); | |
easter2 timestamp := easter_date(next::int); | |
BEGIN | |
return query | |
select t.* | |
from unnest(array[ | |
-- current year | |
(year||'-01-01')::date, (year||'-05-01')::date, | |
(year||'-05-08')::date, (year||'-07-14')::date, | |
(year||'-08-15')::date, (year||'-11-01')::date, | |
(year||'-11-11')::date, (year||'-12-25')::date, | |
easter1::date + 1, easter1::date + 39, easter1::date + 50, | |
-- next year | |
(next||'-01-01')::date, (next||'-05-01')::date, | |
(next||'-05-08')::date, (next||'-07-14')::date, | |
(next||'-08-15')::date, (next||'-11-01')::date, | |
(next||'-11-11')::date, (next||'-12-25')::date, | |
easter2::date + 1, easter2::date + 39, easter2::date + 50 | |
]) t; | |
END; | |
$$ language plpgsql; | |
-- ----------------------------------- | |
-- FUNCTION: evaluate_next_run | |
-- ----------------------------------- | |
CREATE OR REPLACE FUNCTION evaluate_next_run(last_run timestamp with time zone, rule text) | |
RETURNS timestamp with time zone AS $$ | |
DECLARE | |
options text; | |
nextday text; | |
daily interval := '1 day'::interval; | |
monthly interval := '1 mon'::interval; | |
next_run timestamp; | |
BEGIN | |
CASE substring($2 from 'freq=(\w+)') | |
WHEN 'daily' THEN | |
options := substring($2 from 'days=([\w,]+)'); | |
select min(l.next_runs) into next_run from ( | |
select s::timestamp as next_runs | |
from generate_series($1 + daily, $1 + daily * 7, daily) s | |
where options like '%' || extract(dow from s) || '%' | |
except select holiday + ($1)::time from get_holidays() | |
) l; | |
WHEN 'monthly' THEN | |
options := substring($2 from 'days=-([\d]+)'); | |
IF options IS NOT NULL THEN | |
select min(next_runs) into next_run from ( | |
select row_number() over ( | |
partition by extract(mon from next_runs) | |
order by extract(day from next_runs) desc | |
) as rownum, next_runs | |
from ( | |
select s::timestamp as next_runs | |
from generate_series($1 + daily, $1 + monthly * 2 - daily, daily) s | |
where extract(dow from s) in (1,2,3,4,5) | |
except select holiday + ($1)::time from get_holidays() | |
) l1 | |
) l2 where rownum = options::int; | |
ELSE | |
options := substring($2 from 'days=([\d,]+)'); | |
select min(t.day) into nextday | |
from unnest(string_to_array(options, ',')) as t(day) | |
where t.day::int > extract(day from $1); | |
IF nextday IS NULL THEN | |
nextday := split_part(options, ',', 1); | |
END IF; | |
select min(next_runs) into next_run from ( | |
select | |
row_number() over (order by extract(mon from s) desc, extract(day from s)) as rownum, | |
s::timestamp as next_runs | |
from generate_series($1, $1 + monthly - daily, daily) s | |
) l where l.rownum = nextday::int; | |
next_run := evaluate_next_run(next_run - daily, 'freq=daily; days=1,2,3,4,5'); | |
END IF; | |
END CASE; | |
return next_run; | |
END; | |
$$ language plpgsql; |
Sign up for free
to join this conversation on GitHub.
Already have an account?
Sign in to comment