--- /dev/null
+-- Bank holiday prediction functions 22/03/2013 Glyn Astill <glyn@8kb.co.uk>\r
+-- Mostly plagiarised from plpgsql functions posted to PostgreSQL mailing list\r
+-- on 15/05/2007 by Gary Stainburn (gary.stainburn@ringways.co.uk) and converted\r
+-- to plain sql. See:\r
+-- http://www.postgresql.org/message-id/flat/200705151509.41320.gary.stainburn@ringways.co.uk#200705151509.41320.gary.stainburn@ringways.co.uk\r
+-- http://www.postgresql.org/message-id/attachment/21954/bank_holidays.sql\r
+\r
+DROP FUNCTION IF EXISTS public.calculate_easter_sunday(integer);\r
+CREATE OR REPLACE FUNCTION public.calculate_easter_sunday(integer) \r
+RETURNS date AS \r
+$BODY$ \r
+ SELECT \r
+ CASE \r
+ WHEN (((((($1%19)*19)+24)%30)+(((($1%4)*2)+(($1%7)*4)+((((($1%19)*19)+24)%30)*6)+5)%7)) < 10) THEN\r
+ ($1 || '-03-' || (((($1%19)*19)+24)%30)+(((($1%4)*2)+(($1%7)*4)+((((($1%19)*19)+24)%30)*6)+5)%7)+22)::date\r
+ ELSE\r
+ ($1 || '-04-' || (((($1%19)*19)+24)%30)+(((($1%4)*2)+(($1%7)*4)+((((($1%19)*19)+24)%30)*6)+5)%7)-9)::date\r
+ END;\r
+$BODY$ \r
+LANGUAGE SQL IMMUTABLE;\r
+\r
+GRANT EXECUTE ON FUNCTION public.calculate_easter_sunday(integer) TO public;\r
+\r
+--\r
+\r
+DROP FUNCTION IF EXISTS public.calculate_new_year(integer);\r
+CREATE OR REPLACE FUNCTION public.calculate_new_year(integer) \r
+RETURNS date AS \r
+$BODY$ \r
+ SELECT \r
+ CASE extract(dow FROM ($1 || '-01-01')::date)\r
+ WHEN 0 THEN ($1 || '-01-02')::date\r
+ WHEN 6 THEN ($1 || '-01-03')::date\r
+ ELSE ($1 || '-01-01')::date\r
+ END;\r
+$BODY$ \r
+LANGUAGE SQL IMMUTABLE;\r
+\r
+GRANT EXECUTE ON FUNCTION public.calculate_new_year(integer) TO public;\r
+\r
+--\r
+\r
+DROP FUNCTION IF EXISTS public.calculate_christmas_day(integer);\r
+CREATE OR REPLACE FUNCTION public.calculate_christmas_day(integer) \r
+RETURNS date AS \r
+$BODY$ \r
+ SELECT \r
+ CASE extract(dow FROM ($1 || '-12-25')::date)\r
+ WHEN 0 THEN ($1 || '-12-27')::date\r
+ WHEN 6 THEN ($1 || '-12-28')::date\r
+ ELSE ($1 || '-12-25')::date\r
+ END;\r
+$BODY$ \r
+LANGUAGE SQL IMMUTABLE;\r
+\r
+GRANT EXECUTE ON FUNCTION public.calculate_christmas_day(integer) TO public;\r
+--\r
+\r
+DROP FUNCTION IF EXISTS public.calculate_boxing_day(integer);\r
+CREATE OR REPLACE FUNCTION public.calculate_boxing_day(integer) \r
+RETURNS date AS \r
+$BODY$ \r
+ SELECT \r
+ CASE extract(dow FROM ($1 || '-12-26')::date)\r
+ WHEN 0 THEN ($1 || '-12-27')::date\r
+ WHEN 6 THEN ($1 || '-12-28')::date\r
+ ELSE ($1 || '-12-26')::date\r
+ END;\r
+$BODY$ \r
+LANGUAGE SQL IMMUTABLE;\r
+\r
+GRANT EXECUTE ON FUNCTION public.calculate_boxing_day(integer) TO public;\r
+\r
+--\r
+\r
+DROP FUNCTION IF EXISTS public.calculate_may_day(integer);\r
+CREATE OR REPLACE FUNCTION public.calculate_may_day(integer) \r
+RETURNS date AS \r
+$BODY$ \r
+ SELECT \r
+ CASE \r
+ WHEN extract(dow FROM ($1 || '-05-01')::date) < 2 THEN ($1 || '-05-' || 2-extract(dow FROM ($1 || '-05-01')::date))::date\r
+ ELSE ($1 || '-05-' || 9-extract(dow FROM ($1 || '-05-01')::date))::date\r
+ END;\r
+$BODY$ \r
+LANGUAGE SQL IMMUTABLE;\r
+\r
+GRANT EXECUTE ON FUNCTION public.calculate_may_day(integer) TO public;\r
+\r
+--\r
+\r
+DROP FUNCTION IF EXISTS public.calculate_spring_bank_holiday(integer);\r
+CREATE OR REPLACE FUNCTION public.calculate_spring_bank_holiday(integer) \r
+RETURNS date AS \r
+$BODY$ \r
+ SELECT \r
+ CASE extract(dow FROM ($1 || '-05-31')::date)\r
+ WHEN 0 THEN ($1 || '-05-25')::date\r
+ ELSE ($1 || '-05-' || 32-extract(dow FROM ($1 || '-05-31')::date))::date\r
+ END;\r
+$BODY$ \r
+LANGUAGE SQL IMMUTABLE;\r
+\r
+GRANT EXECUTE ON FUNCTION public.calculate_spring_bank_holiday(integer) TO public;\r
+\r
+--\r
+\r
+DROP FUNCTION IF EXISTS public.calculate_whitsun(integer);\r
+CREATE OR REPLACE FUNCTION public.calculate_whitsun(integer) \r
+RETURNS date AS \r
+$BODY$ \r
+ SELECT public.calculate_spring_bank_holiday($1) ;\r
+$BODY$ \r
+LANGUAGE SQL IMMUTABLE;\r
+\r
+GRANT EXECUTE ON FUNCTION public.calculate_whitsun(integer) TO public;\r
+\r
+--\r
+\r
+DROP FUNCTION IF EXISTS public.calculate_summer_bank_holiday(integer);\r
+CREATE OR REPLACE FUNCTION public.calculate_summer_bank_holiday(integer) \r
+RETURNS date AS \r
+$BODY$ \r
+ SELECT \r
+ CASE extract(dow FROM ($1 || '-08-31')::date)\r
+ WHEN 0 THEN ($1 || '-08-25')::date\r
+ ELSE ($1 || '-08-' || 32-extract(dow FROM ($1 || '-08-31')::date))::date\r
+ END;\r
+$BODY$ \r
+LANGUAGE SQL IMMUTABLE;\r
+\r
+GRANT EXECUTE ON FUNCTION public.calculate_summer_bank_holiday(integer) TO public;\r
+\r
+--\r
+\r
+DROP TYPE IF EXISTS public.bank_holidays CASCADE;\r
+CREATE TYPE public.bank_holidays AS\r
+(year integer, description varchar, bank_holiday date);\r
+\r
+DROP FUNCTION IF EXISTS public.calculate_bank_holidays(integer);\r
+CREATE OR REPLACE FUNCTION public.calculate_bank_holidays(integer) \r
+RETURNS SETOF public.bank_holidays AS \r
+$BODY$\r
+ SELECT $1, 'New Years Day', public.calculate_new_year($1)\r
+ UNION\r
+ SELECT $1, 'Good Friday', (public.calculate_easter_sunday($1)-'2 days'::interval)::date\r
+ UNION\r
+ SELECT $1, 'Easter Monday', (public.calculate_easter_sunday($1)+'1 days'::interval)::date\r
+ UNION \r
+ SELECT $1, 'May Day', public.calculate_may_day($1)\r
+ UNION \r
+ SELECT $1, 'Spring Bank Holiday', public.calculate_spring_bank_holiday($1)\r
+ UNION \r
+ SELECT $1, 'Summer Bank Holiday', public.calculate_summer_bank_holiday($1)\r
+ UNION \r
+ SELECT $1, 'Christmas Day', public.calculate_christmas_day($1)\r
+ UNION \r
+ SELECT $1, 'Boxing Day', public.calculate_boxing_day($1)\r
+ ORDER BY 3;\r
+$BODY$\r
+LANGUAGE SQL IMMUTABLE;\r
+\r
+GRANT EXECUTE ON FUNCTION public.calculate_bank_holidays(integer) TO public;\r
+\r
+--\r
+\r
+DROP FUNCTION IF EXISTS public.calculate_bank_holidays(integer, integer);\r
+CREATE OR REPLACE FUNCTION public.calculate_bank_holidays(integer, integer) \r
+RETURNS SETOF bank_holidays AS \r
+$BODY$\r
+ SELECT (public.calculate_bank_holidays(generate_series)).* FROM generate_series($1, $2);\r
+$BODY$\r
+LANGUAGE SQL IMMUTABLE;\r
+\r
+GRANT EXECUTE ON FUNCTION public.calculate_bank_holidays(integer, integer) TO public;\r
+\r
+--\r
+\r
+DROP FUNCTION IF EXISTS public.detail_bank_holiday(date);\r
+CREATE OR REPLACE FUNCTION public.detail_bank_holiday(date) \r
+RETURNS SETOF bank_holidays AS \r
+$BODY$\r
+ SELECT * FROM public.calculate_bank_holidays(extract(year FROM $1)::integer)\r
+ WHERE bank_holiday = $1;\r
+$BODY$\r
+LANGUAGE SQL IMMUTABLE;\r
+\r
+GRANT EXECUTE ON FUNCTION public.detail_bank_holiday(date) TO public;\r
+\r
+--\r
+\r
+DROP FUNCTION IF EXISTS public.is_bank_holiday(date);\r
+CREATE OR REPLACE FUNCTION public.is_bank_holiday(date) \r
+RETURNS boolean AS \r
+$BODY$\r
+ SELECT EXISTS(SELECT 1 FROM public.calculate_bank_holidays(extract(year FROM $1)::integer)\r
+ WHERE bank_holiday = $1);\r
+$BODY$\r
+LANGUAGE SQL IMMUTABLE;\r
+\r
+GRANT EXECUTE ON FUNCTION public.is_bank_holiday(date) TO public;\r
+\r
+--\r
+\r
+DROP FUNCTION IF EXISTS public.count_bank_holidays(date, date);\r
+CREATE OR REPLACE FUNCTION public.count_bank_holidays(date, date) \r
+RETURNS bigint AS \r
+$BODY$\r
+ SELECT count(*) FROM public.calculate_bank_holidays(extract(year FROM $1)::integer, extract(year FROM $2)::integer)\r
+ WHERE bank_holiday BETWEEN $1 AND $2;\r
+$BODY$\r
+LANGUAGE SQL IMMUTABLE;\r
+\r
+GRANT EXECUTE ON FUNCTION public.count_bank_holidays(date, date) TO public;\r
+\r
+--
\ No newline at end of file