Significant further progress on writing RRULE interpreting functions for PostgreSQL.

This commit is contained in:
Andrew McMillan 2008-10-28 11:52:09 +13:00
parent cefdbddd91
commit d7cf594e40
2 changed files with 860 additions and 116 deletions

View File

@ -3,156 +3,196 @@
*
* @package rscds
* @subpackage database
* @author Andrew McMillan <andrew@mcmillan.net.nz>
* @author Andrew McMillan <andrew@morphoss.com>
* @copyright Morphoss Ltd - http://www.morphoss.com/
* @license http://gnu.org/copyleft/gpl.html GNU GPL v2
* @license http://gnu.org/copyleft/gpl.html GNU GPL v2 or later
*
* Coverage of this function set
* - COUNT & UNTIL are handled, generally
* - DAILY frequency, including BYDAY, BYMONTH, BYMONTHDAY
* - WEEKLY frequency, including BYDAY, BYMONTH, BYMONTHDAY, BYSETPOS
* - MONTHLY frequency, including BYDAY, BYMONTH, BYSETPOS
* - YEARLY frequency, including ???
*
* Not covered as yet
* - DAILY: BYYEARDAY, BYWEEKNO, BYMONTHDAY, BYSETPOS*
* - WEEKLY: BYYEARDAY, BYWEEKNO
* - MONTHLY: BYYEARDAY, BYMONTHDAY, BYWEEKNO
* - YEARLY: BYYEARDAY, BYDAY*, BYSETPOS
* - SECONDLY
* - MINUTELY
* - HOURLY
*
*/
-- How many days are there in a particular month?
CREATE or REPLACE FUNCTION rrule_days_in_month( TIMESTAMP WITH TIME ZONE ) RETURNS INT AS $$
-- Create a composite type for the parts of the RRULE.
DROP TYPE rrule_parts CASCADE;
CREATE TYPE rrule_parts AS (
base TIMESTAMP WITH TIME ZONE,
until TIMESTAMP WITH TIME ZONE,
freq TEXT,
count INT,
interval INT,
-- bysecond INT[],
-- byminute INT[],
-- byhour INT[],
bymonthday INT[],
byyearday INT[],
byweekno INT[],
byday TEXT[],
bymonth INT[],
bysetpos INT[],
wkst TEXT
);
-- Create a function to parse the RRULE into it's composite type
CREATE or REPLACE FUNCTION parse_rrule_parts( TIMESTAMP WITH TIME ZONE, TEXT ) RETURNS rrule_parts AS $$
DECLARE
in_time ALIAS FOR $1;
days INT;
basedate ALIAS FOR $1;
repeatrule ALIAS FOR $2;
result rrule_parts%ROWTYPE;
tempstr TEXT;
BEGIN
RETURN date_part( 'days', date_trunc( 'month', in_time + interval '1 month') - interval '1 day' );
result.base := basedate;
result.until := substring(repeatrule from 'UNTIL=([0-9TZ]+)(;|$)');
result.freq := substring(repeatrule from 'FREQ=([A-Z]+)(;|$)');
result.count := substring(repeatrule from 'COUNT=([0-9]+)(;|$)');
result.interval := COALESCE(substring(repeatrule from 'INTERVAL=([0-9]+)(;|$)')::int, 1);
result.wkst := substring(repeatrule from 'WKST=(MO|TU|WE|TH|FR|SA|SU)(;|$)');
/**
* We can do the array conversion as a simple cast, since the strings are simple numbers, with no commas
*/
result.byday := ('{' || substring(repeatrule from 'BYDAY=(([+-]?[0-9]{0,2}(MO|TU|WE|TH|FR|SA|SU),?)+)(;|$)') || '}')::text[];
result.byyearday := ('{' || substring(repeatrule from 'BYYEARDAY=([0-9,+-]+)(;|$)') || '}')::int[];
result.byweekno := ('{' || substring(repeatrule from 'BYWEEKNO=([0-9,+-]+)(;|$)') || '}')::int[];
result.bymonthday := ('{' || substring(repeatrule from 'BYMONTHDAY=([0-9,+-]+)(;|$)') || '}')::int[];
result.bymonth := ('{' || substring(repeatrule from 'BYMONTH=(([+-]?[0-1]?[0-9],?)+)(;|$)') || '}')::int[];
result.bysetpos := ('{' || substring(repeatrule from 'BYSETPOS=(([+-]?[0-9]{1,3},?)+)(;|$)') || '}')::int[];
-- result.bysecond := list_to_array(substring(repeatrule from 'BYSECOND=([0-9,]+)(;|$)'))::int[];
-- result.byminute := list_to_array(substring(repeatrule from 'BYMINUTE=([0-9,]+)(;|$)'))::int[];
-- result.byhour := list_to_array(substring(repeatrule from 'BYHOUR=([0-9,]+)(;|$)'))::int[];
RETURN result;
END;
$$ LANGUAGE 'plpgsql' IMMUTABLE STRICT;
-- Return a SETOF text strings, split on the commas in the original one
CREATE or REPLACE FUNCTION rrule_split_on_commas( TEXT ) RETURNS SETOF TEXT AS $$
DECLARE
in_text ALIAS FOR $1;
part TEXT;
cpos INT;
remainder TEXT;
BEGIN
remainder := in_text;
LOOP
cpos := position( ',' in remainder );
IF cpos = 0 THEN
part := remainder;
EXIT;
ELSE
part := substring( remainder for cpos - 1 );
remainder := substring( remainder from cpos + 1);
RETURN NEXT part;
END IF;
END LOOP;
RETURN NEXT part;
RETURN;
END;
$$ LANGUAGE 'plpgsql' IMMUTABLE STRICT;
-- Return a SETOF dates within the month of a particular date which match a single BYDAY rule specification
CREATE or REPLACE FUNCTION rrule_month_bydayrule_set( TIMESTAMP WITH TIME ZONE, TEXT ) RETURNS SETOF TIMESTAMP WITH TIME ZONE AS $$
-- Return a SETOF dates within the month of a particular date which match a string of BYDAY rule specifications
CREATE or REPLACE FUNCTION rrule_month_byday_set( TIMESTAMP WITH TIME ZONE, TEXT[] ) RETURNS SETOF TIMESTAMP WITH TIME ZONE AS $$
DECLARE
in_time ALIAS FOR $1;
bydayrule ALIAS FOR $2;
byday ALIAS FOR $2;
dayrule TEXT;
i INT;
dow INT;
index INT;
first_dow INT;
each_day TIMESTAMP WITH TIME ZONE;
this_month INT;
results TIMESTAMP WITH TIME ZONE[];
BEGIN
dow := position(substring( bydayrule from '..$') in 'SUMOTUWETHFRSA') / 2;
each_day := date_trunc( 'month', in_time ) + (in_time::time)::interval;
this_month := date_part( 'month', in_time );
first_dow := date_part( 'dow', each_day );
each_day := each_day - ( first_dow::text || 'days')::interval
+ ( dow::text || 'days')::interval
+ CASE WHEN dow > first_dow THEN '1 week'::interval ELSE '0s'::interval END;
IF length(bydayrule) > 2 THEN
index := (substring(bydayrule from '^[0-9-]+'))::int;
-- Possibly we should check that (index != 0) here, which is an error
IF index = 0 THEN
RAISE NOTICE 'Ignored invalid BYDAY rule part "%".', bydayrule;
ELSIF index > 0 THEN
-- The simplest case, such as 2MO for the second monday
each_day := each_day + ((index - 1)::text || ' weeks')::interval;
ELSE
each_day := each_day + '5 weeks'::interval;
WHILE date_part('month', each_day) != this_month LOOP
each_day := each_day - '1 week'::interval;
END LOOP;
-- Note that since index is negative, (-2 + 1) == -1, for example
each_day := each_day + ( (index + 1)::text || ' weeks')::interval ;
END IF;
-- Sometimes (e.g. 5TU or -5WE) there might be no such date in some months
IF date_part('month', each_day) = this_month THEN
RETURN NEXT each_day;
END IF;
ELSE
-- Return all such days that are within the given month
WHILE date_part('month', each_day) = this_month LOOP
RETURN NEXT each_day;
each_day := each_day + '1 week'::interval;
END LOOP;
IF byday IS NULL THEN
-- We still return the single date as a SET
RETURN NEXT in_time;
RETURN;
END IF;
RETURN;
i := 1;
dayrule := byday[i];
WHILE dayrule IS NOT NULL LOOP
dow := position(substring( dayrule from '..$') in 'SUMOTUWETHFRSA') / 2;
each_day := date_trunc( 'month', in_time ) + (in_time::time)::interval;
this_month := date_part( 'month', in_time );
first_dow := date_part( 'dow', each_day );
END;
$$ LANGUAGE 'plpgsql' IMMUTABLE STRICT;
-- Coerce each_day to be the first 'dow' of the month
each_day := each_day - ( first_dow::text || 'days')::interval
+ ( dow::text || 'days')::interval
+ CASE WHEN dow < first_dow THEN '1 week'::interval ELSE '0s'::interval END;
-- RAISE NOTICE 'From "%", for % finding dates. dow=%, this_month=%, first_dow=%', each_day, dayrule, dow, this_month, first_dow;
IF length(dayrule) > 2 THEN
index := (substring(dayrule from '^[0-9-]+'))::int;
-- Return a SETOF dates within the month of a particular date which match a string of BYDAY rule specifications
CREATE or REPLACE FUNCTION rrule_month_byday_set( TIMESTAMP WITH TIME ZONE, TEXT ) RETURNS SETOF TIMESTAMP WITH TIME ZONE AS $$
DECLARE
in_time ALIAS FOR $1;
byday ALIAS FOR $2;
dayrule RECORD;
day RECORD;
BEGIN
IF index = 0 THEN
RAISE NOTICE 'Ignored invalid BYDAY rule part "%".', bydayrule;
ELSIF index > 0 THEN
-- The simplest case, such as 2MO for the second monday
each_day := each_day + ((index - 1)::text || ' weeks')::interval;
ELSE
each_day := each_day + '5 weeks'::interval;
WHILE date_part('month', each_day) != this_month LOOP
each_day := each_day - '1 week'::interval;
END LOOP;
-- Note that since index is negative, (-2 + 1) == -1, for example
index := index + 1;
IF index < 0 THEN
each_day := each_day + (index::text || ' weeks')::interval ;
END IF;
END IF;
FOR dayrule IN SELECT * FROM rrule_split_on_commas( byday ) LOOP
FOR day IN SELECT * FROM rrule_month_bydayrule_set( in_time, dayrule.rrule_split_on_commas ) LOOP
RETURN NEXT day.rrule_month_bydayrule_set;
END LOOP;
-- Sometimes (e.g. 5TU or -5WE) there might be no such date in some months
IF date_part('month', each_day) = this_month THEN
results[date_part('day',each_day)] := each_day;
-- RAISE NOTICE 'Added "%" to list for %', each_day, dayrule;
END IF;
ELSE
-- Return all such days that are within the given month
WHILE date_part('month', each_day) = this_month LOOP
results[date_part('day',each_day)] := each_day;
each_day := each_day + '1 week'::interval;
-- RAISE NOTICE 'Added "%" to list for %', each_day, dayrule;
END LOOP;
END IF;
i := i + 1;
dayrule := byday[i];
END LOOP;
FOR i IN 1..31 LOOP
IF results[i] IS NOT NULL THEN
RETURN NEXT results[i];
END IF;
END LOOP;
RETURN;
END;
$$ LANGUAGE 'plpgsql' IMMUTABLE STRICT;
$$ LANGUAGE 'plpgsql' IMMUTABLE;
-- Return a SETOF dates within the month of a particular date which match a string of BYDAY rule specifications
CREATE or REPLACE FUNCTION rrule_month_bymonthday_set( TIMESTAMP WITH TIME ZONE, TEXT ) RETURNS SETOF TIMESTAMP WITH TIME ZONE AS $$
CREATE or REPLACE FUNCTION rrule_month_bymonthday_set( TIMESTAMP WITH TIME ZONE, INT[] ) RETURNS SETOF TIMESTAMP WITH TIME ZONE AS $$
DECLARE
in_time ALIAS FOR $1;
bymonthday ALIAS FOR $2;
dayrule RECORD;
daysinmonth INT;
month_start TIMESTAMP WITH TIME ZONE;
dayoffset INT;
daysinmonth INT;
i INT;
BEGIN
daysinmonth := rrule_days_in_month(in_time);
month_start := date_trunc( 'month', in_time ) + (in_time::time)::interval;
month_start := date_trunc( 'month', base_date ) + (base_date::time)::interval;
daysinmonth := date_part( 'days', (month_start + interval '1 month') - interval '1 day' );
FOR dayrule IN SELECT * FROM rrule_split_on_commas( bymonthday ) LOOP
dayoffset := dayrule.rrule_split_on_commas::int;
IF dayoffset = 0 THEN
RAISE NOTICE 'Ignored invalid BYMONTHDAY part "%".', dayrule.rrule_split_on_commas;
dayoffset := 0;
ELSIF dayoffset > daysinmonth THEN
dayoffset := 0;
ELSIF dayoffset < (-1 * daysinmonth) THEN
dayoffset := 0;
ELSIF dayoffset > 0 THEN
RETURN NEXT month_start + ((dayoffset - 1)::text || 'days')::interval;
FOR i IN 1..31 LOOP
EXIT WHEN bymonthday[i] IS NULL;
CONTINUE WHEN bymonthday[i] > daysinmonth;
CONTINUE WHEN bymonthday[i] < (-1 * daysinmonth);
IF bymonthday[i] > 0 THEN
RETURN NEXT month_start + ((bymonthday[i] - 1)::text || 'days')::interval;
ELSIF bymonthday[i] < 0 THEN
RETURN NEXT month_start + ((daysinmonth + bymonthday[i])::text || 'days')::interval;
ELSE
RETURN NEXT month_start + ((daysinmonth + dayoffset)::text || 'days')::interval;
RAISE NOTICE 'Ignored invalid BYMONTHDAY part "%".', bymonthday[i];
END IF;
END LOOP;
RETURN;
@ -161,27 +201,38 @@ END;
$$ LANGUAGE 'plpgsql' IMMUTABLE STRICT;
-- Return a SETOF dates within the week of a particular date which match a single BYDAY rule specification
CREATE or REPLACE FUNCTION rrule_week_byday_set( TIMESTAMP WITH TIME ZONE, TEXT ) RETURNS SETOF TIMESTAMP WITH TIME ZONE AS $$
CREATE or REPLACE FUNCTION rrule_week_byday_set( TIMESTAMP WITH TIME ZONE, TEXT[] ) RETURNS SETOF TIMESTAMP WITH TIME ZONE AS $$
DECLARE
in_time ALIAS FOR $1;
byweekday ALIAS FOR $2;
dayrule RECORD;
byday ALIAS FOR $2;
dayrule TEXT;
dow INT;
our_day TIMESTAMP WITH TIME ZONE;
i INT;
BEGIN
IF byday IS NULL THEN
-- We still return the single date as a SET
RETURN NEXT in_time;
RETURN;
END IF;
our_day := date_trunc( 'week', in_time ) + (in_time::time)::interval;
FOR dayrule IN SELECT * FROM rrule_split_on_commas( byweekday ) LOOP
dow := position(substring( dayrule.rrule_split_on_commas from '..$') in 'SUMOTUWETHFRSA') / 2;
i := 1;
dayrule := byday[i];
WHILE dayrule IS NOT NULL LOOP
dow := position(dayrule in 'SUMOTUWETHFRSA') / 2;
RETURN NEXT our_day + ((dow - 1)::text || 'days')::interval;
i := i + 1;
dayrule := byday[i];
END LOOP;
RETURN;
END;
$$ LANGUAGE 'plpgsql' IMMUTABLE STRICT;
$$ LANGUAGE 'plpgsql' IMMUTABLE;
CREATE or REPLACE FUNCTION event_has_exceptions( TEXT ) RETURNS BOOLEAN AS $$
@ -189,3 +240,280 @@ CREATE or REPLACE FUNCTION event_has_exceptions( TEXT ) RETURNS BOOLEAN AS $$
$$ LANGUAGE 'sql' IMMUTABLE STRICT;
------------------------------------------------------------------------------------------------------
-- Test the weekday of this date against the array of weekdays from the byday rule
------------------------------------------------------------------------------------------------------
CREATE or REPLACE FUNCTION test_byday_rule( TIMESTAMP WITH TIME ZONE, TEXT[] ) RETURNS BOOLEAN AS $$
DECLARE
testme ALIAS FOR $1;
byday ALIAS FOR $2;
i INT;
dow TEXT;
BEGIN
IF byday IS NOT NULL THEN
dow := substring( to_char( testme, 'DY') for 2 from 1);
FOR i IN 1..7 LOOP
IF byday[i] IS NULL THEN
RETURN FALSE;
END IF;
EXIT WHEN dow = byday[i];
END LOOP;
END IF;
RETURN TRUE;
END;
$$ LANGUAGE 'plpgsql' IMMUTABLE;
------------------------------------------------------------------------------------------------------
-- Test the month of this date against the array of months from the rule
------------------------------------------------------------------------------------------------------
CREATE or REPLACE FUNCTION test_bymonth_rule( TIMESTAMP WITH TIME ZONE, INT[] ) RETURNS BOOLEAN AS $$
DECLARE
testme ALIAS FOR $1;
bymonth ALIAS FOR $2;
i INT;
month INT;
BEGIN
IF bymonth IS NOT NULL THEN
month := date_part( 'month', testme );
FOR i IN 1..12 LOOP
IF bymonth[i] IS NULL THEN
RETURN FALSE;
END IF;
EXIT WHEN month = bymonth[i];
END LOOP;
END IF;
RETURN TRUE;
END;
$$ LANGUAGE 'plpgsql' IMMUTABLE;
------------------------------------------------------------------------------------------------------
-- Test the month of this date against the array of months from the rule
------------------------------------------------------------------------------------------------------
CREATE or REPLACE FUNCTION test_bymonthday_rule( TIMESTAMP WITH TIME ZONE, INT[] ) RETURNS BOOLEAN AS $$
DECLARE
testme ALIAS FOR $1;
bymonthday ALIAS FOR $2;
i INT;
dom INT;
BEGIN
IF bymonthday IS NOT NULL THEN
dom := date_part( 'day', testme);
FOR i IN 1..31 LOOP
IF bymonthday[i] IS NULL THEN
RETURN FALSE;
END IF;
EXIT WHEN dom = bymonthday[i];
END LOOP;
END IF;
RETURN TRUE;
END;
$$ LANGUAGE 'plpgsql' IMMUTABLE;
------------------------------------------------------------------------------------------------------
-- Return another day's worth of events
------------------------------------------------------------------------------------------------------
CREATE or REPLACE FUNCTION daily_set( TIMESTAMP WITH TIME ZONE, rrule_parts ) RETURNS SETOF TIMESTAMP WITH TIME ZONE AS $$
DECLARE
after ALIAS FOR $1;
rrule ALIAS FOR $2;
BEGIN
-- Since we don't do BYHOUR, BYMINUTE or BYSECOND yet this becomes trivial
RETURN NEXT after;
END;
$$ LANGUAGE 'plpgsql' IMMUTABLE STRICT;
------------------------------------------------------------------------------------------------------
-- Return another week's worth of events
------------------------------------------------------------------------------------------------------
CREATE or REPLACE FUNCTION weekly_set( TIMESTAMP WITH TIME ZONE, rrule_parts ) RETURNS SETOF TIMESTAMP WITH TIME ZONE AS $$
DECLARE
after ALIAS FOR $1;
rrule ALIAS FOR $2;
valid_date TIMESTAMP WITH TIME ZONE;
curse REFCURSOR;
setpos INT;
i INT;
BEGIN
OPEN curse SCROLL FOR SELECT r FROM rrule_week_byday_set(after, rrule.byday ) r;
IF rrule.bysetpos IS NULL THEN
LOOP
FETCH curse INTO valid_date;
EXIT WHEN NOT FOUND;
RETURN NEXT valid_date;
END LOOP;
ELSE
i := 1;
setpos := rrule.bysetpos[i];
WHILE setpos IS NOT NULL LOOP
IF setpos > 0 THEN
FETCH ABSOLUTE setpos FROM curse INTO valid_date;
ELSE
setpos := setpos + 1;
MOVE LAST IN curse;
FETCH RELATIVE setpos FROM curse INTO valid_date;
END IF;
IF next_base IS NOT NULL THEN
RETURN NEXT valid_date;
END IF;
i := i + 1;
setpos := rrule.bysetpos[i];
END LOOP;
END IF;
END;
$$ LANGUAGE 'plpgsql' IMMUTABLE STRICT;
------------------------------------------------------------------------------------------------------
-- Return another month's worth of events
------------------------------------------------------------------------------------------------------
CREATE or REPLACE FUNCTION monthly_set( TIMESTAMP WITH TIME ZONE, rrule_parts ) RETURNS SETOF TIMESTAMP WITH TIME ZONE AS $$
DECLARE
after ALIAS FOR $1;
rrule ALIAS FOR $2;
valid_date TIMESTAMP WITH TIME ZONE;
curse REFCURSOR;
setpos INT;
i INT;
BEGIN
-- Need to investigate whether it is legal to set both of these, and whether
-- we are correct to UNION the results, or whether we should INTERSECT them.
OPEN curse SCROLL FOR SELECT r FROM rrule_month_byday_set(after, rrule.byday ) r
UNION SELECT r FROM rrule_month_bymonthday_set(after, rrule.bymonthday ) r
ORDER BY 1;
IF rrule.bysetpos IS NULL THEN
LOOP
FETCH curse INTO valid_date;
EXIT WHEN NOT FOUND;
RETURN NEXT valid_date;
END LOOP;
ELSE
i := 1;
setpos := rrule.bysetpos[i];
WHILE setpos IS NOT NULL LOOP
IF setpos > 0 THEN
FETCH ABSOLUTE setpos FROM curse INTO valid_date;
ELSE
setpos := setpos + 1;
MOVE LAST IN curse;
FETCH RELATIVE setpos FROM curse INTO valid_date;
END IF;
IF valid_date IS NOT NULL THEN
RETURN NEXT valid_date;
END IF;
i := i + 1;
setpos := rrule.bysetpos[i];
END LOOP;
END IF;
END;
$$ LANGUAGE 'plpgsql' IMMUTABLE STRICT;
CREATE or REPLACE FUNCTION yearly_set( TIMESTAMP WITH TIME ZONE, rrule_parts ) RETURNS SETOF TIMESTAMP WITH TIME ZONE AS $$
DECLARE
after ALIAS FOR $1;
rrule ALIAS FOR $2;
current_base TIMESTAMP WITH TIME ZONE;
rr rrule_parts;
i INT;
BEGIN
IF rrule.bymonth IS NOT NULL THEN
-- As far as I can see there is extremely little difference between YEARLY;BYMONTH and MONTHLY;BYMONTH except the effect of BYSETPOS
rr := rrule;
rr.bysetpos := NULL;
FOR i IN 1..12 LOOP
EXIT WHEN rr.bymonth[i] IS NULL;
current_base := date_trunc( 'year', after ) + ((rr.bymonth[i] - 1)::text || ' months')::interval + (after::time)::interval;
RETURN QUERY SELECT r FROM monthly_set(current_base,rr) r;
END LOOP;
ELSE
-- We don't yet implement byweekno, byblah
RETURN NEXT after;
END IF;
END;
$$ LANGUAGE 'plpgsql' IMMUTABLE STRICT;
CREATE or REPLACE FUNCTION event_instances( TIMESTAMP WITH TIME ZONE, TEXT )
RETURNS SETOF TIMESTAMP WITH TIME ZONE AS $$
DECLARE
basedate ALIAS FOR $1;
repeatrule ALIAS FOR $2;
loopcount INT;
loopmax INT;
base_day TIMESTAMP WITH TIME ZONE;
current_base TIMESTAMP WITH TIME ZONE;
current TIMESTAMP WITH TIME ZONE;
rrule rrule_parts%ROWTYPE;
BEGIN
loopcount := 0;
loopmax := 500;
SELECT * INTO rrule FROM parse_rrule_parts( basedate, repeatrule );
IF rrule.count IS NOT NULL THEN
loopmax := rrule.count;
END IF;
current_base := basedate;
base_day := date_trunc('day',basedate);
WHILE loopcount < loopmax LOOP
IF rrule.freq = 'DAILY' THEN
FOR current IN SELECT d FROM daily_set(current_base,rrule) d WHERE d >= base_day LOOP
IF test_byday_rule(current,rrule.byday) AND test_bymonthday_rule(current,rrule.bymonthday) AND test_bymonth_rule(current,rrule.bymonth) THEN
EXIT WHEN rrule.until IS NOT NULL AND current > rrule.until;
RETURN NEXT current;
loopcount := loopcount + 1;
EXIT WHEN loopcount >= loopmax;
END IF;
END LOOP;
current_base := current_base + (rrule.interval::text || ' days')::interval;
ELSIF rrule.freq = 'WEEKLY' THEN
FOR current IN SELECT w FROM weekly_set(current_base,rrule) w WHERE w >= base_day LOOP
IF test_bymonthday_rule(current,rrule.bymonthday) AND test_bymonth_rule(current,rrule.bymonth) THEN
EXIT WHEN rrule.until IS NOT NULL AND current > rrule.until;
RETURN NEXT current;
loopcount := loopcount + 1;
EXIT WHEN loopcount >= loopmax;
END IF;
END LOOP;
current_base := current_base + (rrule.interval::text || ' weeks')::interval;
ELSIF rrule.freq = 'MONTHLY' THEN
FOR current IN SELECT m FROM monthly_set(current_base,rrule) m WHERE m >= base_day LOOP
IF test_bymonth_rule(current,rrule.bymonth) THEN
EXIT WHEN rrule.until IS NOT NULL AND current > rrule.until;
RETURN NEXT current;
loopcount := loopcount + 1;
EXIT WHEN loopcount >= loopmax;
END IF;
END LOOP;
current_base := current_base + (rrule.interval::text || ' months')::interval;
ELSIF rrule.freq = 'YEARLY' THEN
FOR current IN SELECT y FROM yearly_set(current_base,rrule) y WHERE y >= base_day LOOP
EXIT WHEN rrule.until IS NOT NULL AND current > rrule.until;
RETURN NEXT current;
loopcount := loopcount + 1;
EXIT WHEN loopcount >= loopmax;
END LOOP;
current_base := current_base + (rrule.interval::text || ' years')::interval;
ELSE
RAISE NOTICE 'A frequency of "%" is not handled', rrule.freq;
RETURN;
END IF;
EXIT WHEN rrule.until IS NOT NULL AND current > rrule.until;
END LOOP;
-- RETURN QUERY;
END;
$$ LANGUAGE 'plpgsql' IMMUTABLE STRICT;

416
dba/rrule_tests.sql Normal file
View File

@ -0,0 +1,416 @@
-- --------------------------------------------------------------------
-- This file is a set of tests for the RRULE sql functions taken from
-- the examples in RFC2445 section 4.8.5.4
-- --------------------------------------------------------------------
-- --------------------------------------------------------------------
-- Daily for 10 occurrences:
--
-- DTSTART;TZID=US-Eastern:19970902T090000
-- RRULE:FREQ=DAILY;COUNT=10
--
-- ==> (1997 9:00 AM EDT)September 2-11
--- SELECT * FROM event_instances('19970902T090000', 'FREQ=DAILY;COUNT=10' ) LIMIT 20;
--
-- --------------------------------------------------------------------
-- Daily until December 24, 1997:
--
-- DTSTART;TZID=US-Eastern:19970902T090000
-- RRULE:FREQ=DAILY;UNTIL=19971224T000000Z
--
-- ==> (1997 9:00 AM EDT)September 2-30;October 1-25
-- (1997 9:00 AM EST)October 26-31;November 1-30;December 1-23
--- SELECT * FROM event_instances('19970902T090000', 'FREQ=DAILY;UNTIL=19971224T000000' ) LIMIT 500;
--
-- --------------------------------------------------------------------
-- Every other day - forever:
--
-- DTSTART;TZID=US-Eastern:19970902T090000
-- RRULE:FREQ=DAILY;INTERVAL=2
-- ==> (1997 9:00 AM EDT)September2,4,6,8...24,26,28,30;
-- October 2,4,6...20,22,24
-- (1997 9:00 AM EST)October 26,28,30;November 1,3,5,7...25,27,29;
-- Dec 1,3,...
--
--- SELECT * FROM event_instances('19970902T090000', 'FREQ=DAILY;INTERVAL=2' ) LIMIT 20;
-- --------------------------------------------------------------------
-- Every 10 days, 5 occurrences:
--
-- DTSTART;TZID=US-Eastern:19970902T090000
-- RRULE:FREQ=DAILY;INTERVAL=10;COUNT=5
--
-- ==> (1997 9:00 AM EDT)September 2,12,22;October 2,12
--
--- SELECT * FROM event_instances('19970902T090000', 'FREQ=DAILY;INTERVAL=10;COUNT=5' ) LIMIT 500;
-- --------------------------------------------------------------------
-- Everyday in January, for 3 years:
--
-- DTSTART;TZID=US-Eastern:19980101T090000
-- RRULE:FREQ=YEARLY;UNTIL=20000131T090000Z;
-- BYMONTH=1;BYDAY=SU,MO,TU,WE,TH,FR,SA
-- or
-- RRULE:FREQ=DAILY;UNTIL=20000131T090000Z;BYMONTH=1
--
-- ==> (1998 9:00 AM EDT)January 1-31
-- (1999 9:00 AM EDT)January 1-31
-- (2000 9:00 AM EDT)January 1-31
--
--- SELECT * FROM event_instances('19970902T090000', 'FREQ=DAILY;UNTIL=20000131T090000Z;BYMONTH=1' ) LIMIT 500;
-- --------------------------------------------------------------------
-- Weekly for 10 occurrences
--
-- DTSTART;TZID=US-Eastern:19970902T090000
-- RRULE:FREQ=WEEKLY;COUNT=10
--
-- ==> (1997 9:00 AM EDT)September 2,9,16,23,30;October 7,14,21
-- (1997 9:00 AM EST)October 28;November 4
--- SELECT * FROM event_instances('19970902T090000', 'FREQ=WEEKLY;COUNT=10' ) LIMIT 500;
--
-- --------------------------------------------------------------------
-- Weekly until December 24, 1997
--
-- DTSTART;TZID=US-Eastern:19970902T090000
-- RRULE:FREQ=WEEKLY;UNTIL=19971224T000000Z
--
-- ==> (1997 9:00 AM EDT)September 2,9,16,23,30;October 7,14,21
-- (1997 9:00 AM EST)October 28;November 4,11,18,25;
-- December 2,9,16,23
--- SELECT * FROM event_instances('19970902T090000', 'FREQ=WEEKLY;UNTIL=19971224T000000Z' ) LIMIT 500;
--
-- --------------------------------------------------------------------
-- Every other week - forever:
--
-- DTSTART;TZID=US-Eastern:19970902T090000
-- RRULE:FREQ=WEEKLY;INTERVAL=2;WKST=SU
--
-- ==> (1997 9:00 AM EDT)September 2,16,30;October 14
-- (1997 9:00 AM EST)October 28;November 11,25;December 9,23
-- (1998 9:00 AM EST)January 6,20;February
-- ...
--- SELECT * FROM event_instances('19970902T090000', 'FREQ=WEEKLY;INTERVAL=2;WKST=SU' ) LIMIT 12;
--
-- --------------------------------------------------------------------
-- Weekly on Tuesday and Thursday for 5 weeks:
--
-- DTSTART;TZID=US-Eastern:19970902T090000
-- RRULE:FREQ=WEEKLY;UNTIL=19971007T000000Z;WKST=SU;BYDAY=TU,TH
-- or
-- RRULE:FREQ=WEEKLY;COUNT=10;WKST=SU;BYDAY=TU,TH
--
-- ==> (1997 9:00 AM EDT)September 2,4,9,11,16,18,23,25,30;October 2
---- !SELECT * FROM event_instances('19970902T090000', 'FREQ=WEEKLY;UNTIL=19971007T000000Z;WKST=SU;BYDAY=TU,TH' ) LIMIT 500;
---- !SELECT * FROM event_instances('19970902T090000', 'FREQ=WEEKLY;COUNT=10;WKST=SU;BYDAY=TU,TH' ) LIMIT 500;
--
-- --------------------------------------------------------------------
-- Every other week on Monday, Wednesday and Friday until December 24,
-- 1997, but starting on Tuesday, September 2, 1997:
--
-- DTSTART;TZID=US-Eastern:19970902T090000
-- RRULE:FREQ=WEEKLY;INTERVAL=2;UNTIL=19971224T000000Z;WKST=SU;
-- BYDAY=MO,WE,FR
-- ==> (1997 9:00 AM EDT)September 2,3,5,15,17,19,29;October
-- 1,3,13,15,17
-- (1997 9:00 AM EST)October 27,29,31;November 10,12,14,24,26,28;
-- December 8,10,12,22
--
-- --------------------------------------------------------------------
-- Every other week on Tuesday and Thursday, for 8 occurrences:
--
-- DTSTART;TZID=US-Eastern:19970902T090000
-- RRULE:FREQ=WEEKLY;INTERVAL=2;COUNT=8;WKST=SU;BYDAY=TU,TH
--
-- ==> (1997 9:00 AM EDT)September 2,4,16,18,30;October 2,14,16
--
-- --------------------------------------------------------------------
-- Monthly on the 1st Friday for ten occurrences:
--
-- DTSTART;TZID=US-Eastern:19970905T090000
-- RRULE:FREQ=MONTHLY;COUNT=10;BYDAY=1FR
--
-- ==> (1997 9:00 AM EDT)September 5;October 3
-- (1997 9:00 AM EST)November 7;Dec 5
-- (1998 9:00 AM EST)January 2;February 6;March 6;April 3
-- (1998 9:00 AM EDT)May 1;June 5
--
-- --------------------------------------------------------------------
-- Monthly on the 1st Friday until December 24, 1997:
--
-- DTSTART;TZID=US-Eastern:19970905T090000
-- RRULE:FREQ=MONTHLY;UNTIL=19971224T000000Z;BYDAY=1FR
--
-- ==> (1997 9:00 AM EDT)September 5;October 3
-- (1997 9:00 AM EST)November 7;December 5
--
-- --------------------------------------------------------------------
-- Every other month on the 1st and last Sunday of the month for 10
-- occurrences:
--
-- DTSTART;TZID=US-Eastern:19970907T090000
-- RRULE:FREQ=MONTHLY;INTERVAL=2;COUNT=10;BYDAY=1SU,-1SU
--
-- ==> (1997 9:00 AM EDT)September 7,28
-- (1997 9:00 AM EST)November 2,30
-- (1998 9:00 AM EST)January 4,25;March 1,29
-- (1998 9:00 AM EDT)May 3,31
--
-- --------------------------------------------------------------------
-- Monthly on the second to last Monday of the month for 6 months:
--
-- DTSTART;TZID=US-Eastern:19970922T090000
-- RRULE:FREQ=MONTHLY;COUNT=6;BYDAY=-2MO
--
-- ==> (1997 9:00 AM EDT)September 22;October 20
-- (1997 9:00 AM EST)November 17;December 22
-- (1998 9:00 AM EST)January 19;February 16
--
-- --------------------------------------------------------------------
-- Monthly on the third to the last day of the month, forever:
--
-- DTSTART;TZID=US-Eastern:19970928T090000
-- RRULE:FREQ=MONTHLY;BYMONTHDAY=-3
--
-- ==> (1997 9:00 AM EDT)September 28
-- (1997 9:00 AM EST)October 29;November 28;December 29
-- (1998 9:00 AM EST)January 29;February 26
-- ...
--
-- --------------------------------------------------------------------
-- Monthly on the 2nd and 15th of the month for 10 occurrences:
--
-- DTSTART;TZID=US-Eastern:19970902T090000
-- RRULE:FREQ=MONTHLY;COUNT=10;BYMONTHDAY=2,15
--
-- ==> (1997 9:00 AM EDT)September 2,15;October 2,15
-- (1997 9:00 AM EST)November 2,15;December 2,15
-- (1998 9:00 AM EST)January 2,15
--
-- --------------------------------------------------------------------
-- Monthly on the first and last day of the month for 10 occurrences:
--
-- DTSTART;TZID=US-Eastern:19970930T090000
-- RRULE:FREQ=MONTHLY;COUNT=10;BYMONTHDAY=1,-1
--
-- ==> (1997 9:00 AM EDT)September 30;October 1
-- (1997 9:00 AM EST)October 31;November 1,30;December 1,31
-- (1998 9:00 AM EST)January 1,31;February 1
--
-- --------------------------------------------------------------------
-- Every 18 months on the 10th thru 15th of the month for 10
-- occurrences:
--
-- DTSTART;TZID=US-Eastern:19970910T090000
-- RRULE:FREQ=MONTHLY;INTERVAL=18;COUNT=10;BYMONTHDAY=10,11,12,13,14,
-- 15
--
-- ==> (1997 9:00 AM EDT)September 10,11,12,13,14,15
-- (1999 9:00 AM EST)March 10,11,12,13
--
-- --------------------------------------------------------------------
-- Every Tuesday, every other month:
--
-- DTSTART;TZID=US-Eastern:19970902T090000
-- RRULE:FREQ=MONTHLY;INTERVAL=2;BYDAY=TU
--
-- ==> (1997 9:00 AM EDT)September 2,9,16,23,30
-- (1997 9:00 AM EST)November 4,11,18,25
-- (1998 9:00 AM EST)January 6,13,20,27;March 3,10,17,24,31
-- ...
--
-- --------------------------------------------------------------------
-- Yearly in June and July for 10 occurrences:
--
-- DTSTART;TZID=US-Eastern:19970610T090000
-- RRULE:FREQ=YEARLY;COUNT=10;BYMONTH=6,7
-- ==> (1997 9:00 AM EDT)June 10;July 10
-- (1998 9:00 AM EDT)June 10;July 10
-- (1999 9:00 AM EDT)June 10;July 10
-- (2000 9:00 AM EDT)June 10;July 10
-- (2001 9:00 AM EDT)June 10;July 10
-- Note: Since none of the BYDAY, BYMONTHDAY or BYYEARDAY components
-- are specified, the day is gotten from DTSTART
--
-- --------------------------------------------------------------------
-- Every other year on January, February, and March for 10 occurrences:
--
-- DTSTART;TZID=US-Eastern:19970310T090000
-- RRULE:FREQ=YEARLY;INTERVAL=2;COUNT=10;BYMONTH=1,2,3
--
-- ==> (1997 9:00 AM EST)March 10
-- (1999 9:00 AM EST)January 10;February 10;March 10
-- (2001 9:00 AM EST)January 10;February 10;March 10
-- (2003 9:00 AM EST)January 10;February 10;March 10
--
-- --------------------------------------------------------------------
-- Every 3rd year on the 1st, 100th and 200th day for 10 occurrences:
--
-- DTSTART;TZID=US-Eastern:19970101T090000
-- RRULE:FREQ=YEARLY;INTERVAL=3;COUNT=10;BYYEARDAY=1,100,200
--
-- ==> (1997 9:00 AM EST)January 1
-- (1997 9:00 AM EDT)April 10;July 19
-- (2000 9:00 AM EST)January 1
-- (2000 9:00 AM EDT)April 9;July 18
-- (2003 9:00 AM EST)January 1
-- (2003 9:00 AM EDT)April 10;July 19
-- (2006 9:00 AM EST)January 1
--
-- --------------------------------------------------------------------
-- Every 20th Monday of the year, forever:
-- DTSTART;TZID=US-Eastern:19970519T090000
-- RRULE:FREQ=YEARLY;BYDAY=20MO
--
-- ==> (1997 9:00 AM EDT)May 19
-- (1998 9:00 AM EDT)May 18
-- (1999 9:00 AM EDT)May 17
-- ...
--
-- --------------------------------------------------------------------
-- Monday of week number 20 (where the default start of the week is
-- Monday), forever:
--
-- DTSTART;TZID=US-Eastern:19970512T090000
-- RRULE:FREQ=YEARLY;BYWEEKNO=20;BYDAY=MO
--
-- ==> (1997 9:00 AM EDT)May 12
-- (1998 9:00 AM EDT)May 11
-- (1999 9:00 AM EDT)May 17
-- ...
--
-- --------------------------------------------------------------------
-- Every Thursday in March, forever:
--
-- DTSTART;TZID=US-Eastern:19970313T090000
-- RRULE:FREQ=YEARLY;BYMONTH=3;BYDAY=TH
--
-- ==> (1997 9:00 AM EST)March 13,20,27
-- (1998 9:00 AM EST)March 5,12,19,26
-- (1999 9:00 AM EST)March 4,11,18,25
-- ...
--
-- --------------------------------------------------------------------
-- Every Thursday, but only during June, July, and August, forever:
--
-- DTSTART;TZID=US-Eastern:19970605T090000
-- RRULE:FREQ=YEARLY;BYDAY=TH;BYMONTH=6,7,8
--
-- ==> (1997 9:00 AM EDT)June 5,12,19,26;July 3,10,17,24,31;
-- August 7,14,21,28
-- (1998 9:00 AM EDT)June 4,11,18,25;July 2,9,16,23,30;
-- August 6,13,20,27
-- (1999 9:00 AM EDT)June 3,10,17,24;July 1,8,15,22,29;
-- August 5,12,19,26
-- ...
--
-- --------------------------------------------------------------------
-- Every Friday the 13th, forever:
--
-- DTSTART;TZID=US-Eastern:19970902T090000
-- EXDATE;TZID=US-Eastern:19970902T090000
-- RRULE:FREQ=MONTHLY;BYDAY=FR;BYMONTHDAY=13
--
-- ==> (1998 9:00 AM EST)February 13;March 13;November 13
-- (1999 9:00 AM EDT)August 13
-- (2000 9:00 AM EDT)October 13
-- ...
--
-- --------------------------------------------------------------------
-- The first Saturday that follows the first Sunday of the month,
-- forever:
--
-- DTSTART;TZID=US-Eastern:19970913T090000
-- RRULE:FREQ=MONTHLY;BYDAY=SA;BYMONTHDAY=7,8,9,10,11,12,13
--
-- ==> (1997 9:00 AM EDT)September 13;October 11
-- (1997 9:00 AM EST)November 8;December 13
-- (1998 9:00 AM EST)January 10;February 7;March 7
-- (1998 9:00 AM EDT)April 11;May 9;June 13...
-- ...
--
-- --------------------------------------------------------------------
-- Every four years, the first Tuesday after a Monday in November,
-- forever (U.S. Presidential Election day):
--
-- DTSTART;TZID=US-Eastern:19961105T090000
-- RRULE:FREQ=YEARLY;INTERVAL=4;BYMONTH=11;BYDAY=TU;BYMONTHDAY=2,3,4,
-- 5,6,7,8
--
-- ==> (1996 9:00 AM EST)November 5
-- (2000 9:00 AM EST)November 7
-- (2004 9:00 AM EST)November 2
-- ...
--
-- --------------------------------------------------------------------
-- The 3rd instance into the month of one of Tuesday, Wednesday or
-- Thursday, for the next 3 months:
--
-- DTSTART;TZID=US-Eastern:19970904T090000
-- RRULE:FREQ=MONTHLY;COUNT=3;BYDAY=TU,WE,TH;BYSETPOS=3
--
-- ==> (1997 9:00 AM EDT)September 4;October 7
-- (1997 9:00 AM EST)November 6
--
-- --------------------------------------------------------------------
-- The 2nd to last weekday of the month:
--
-- DTSTART;TZID=US-Eastern:19970929T090000
-- RRULE:FREQ=MONTHLY;BYDAY=MO,TU,WE,TH,FR;BYSETPOS=-2
--
-- ==> (1997 9:00 AM EDT)September 29
-- (1997 9:00 AM EST)October 30;November 27;December 30
-- (1998 9:00 AM EST)January 29;February 26;March 30
-- ...
--
-- --------------------------------------------------------------------
-- Every 3 hours from 9:00 AM to 5:00 PM on a specific day:
--
-- DTSTART;TZID=US-Eastern:19970902T090000
-- RRULE:FREQ=HOURLY;INTERVAL=3;UNTIL=19970902T170000Z
--
-- ==> (September 2, 1997 EDT)09:00,12:00,15:00
--
-- --------------------------------------------------------------------
-- Every 15 minutes for 6 occurrences:
--
-- DTSTART;TZID=US-Eastern:19970902T090000
-- RRULE:FREQ=MINUTELY;INTERVAL=15;COUNT=6
--
-- ==> (September 2, 1997 EDT)09:00,09:15,09:30,09:45,10:00,10:15
--
-- --------------------------------------------------------------------
-- Every hour and a half for 4 occurrences:
--
-- DTSTART;TZID=US-Eastern:19970902T090000
-- RRULE:FREQ=MINUTELY;INTERVAL=90;COUNT=4
--
-- ==> (September 2, 1997 EDT)09:00,10:30;12:00;13:30
--
-- --------------------------------------------------------------------
-- Every 20 minutes from 9:00 AM to 4:40 PM every day:
--
-- DTSTART;TZID=US-Eastern:19970902T090000
-- RRULE:FREQ=DAILY;BYHOUR=9,10,11,12,13,14,15,16;BYMINUTE=0,20,40
-- or
-- RRULE:FREQ=MINUTELY;INTERVAL=20;BYHOUR=9,10,11,12,13,14,15,16
--
-- ==> (September 2, 1997 EDT)9:00,9:20,9:40,10:00,10:20,
-- ... 16:00,16:20,16:40
-- (September 3, 1997 EDT)9:00,9:20,9:40,10:00,10:20,
-- ...16:00,16:20,16:40
-- ...
---- !! SELECT * FROM event_instances('19970902T090000', 'FREQ=DAILY;BYHOUR=9,10,11,12,13,14,15,16;BYMINUTE=0,20,40' ) LIMIT 500;
--
-- --------------------------------------------------------------------
-- An example where the days generated makes a difference because of
-- WKST:
--
-- DTSTART;TZID=US-Eastern:19970805T090000
-- RRULE:FREQ=WEEKLY;INTERVAL=2;COUNT=4;BYDAY=TU,SU;WKST=MO
--
-- ==> (1997 EDT)Aug 5,10,19,24
--
-- changing only WKST from MO to SU, yields different results...
--
-- DTSTART;TZID=US-Eastern:19970805T090000
-- RRULE:FREQ=WEEKLY;INTERVAL=2;COUNT=4;BYDAY=TU,SU;WKST=SU
-- ==> (1997 EDT)August 5,17,19,31
--
--