7828f877c8 2010-08-07 1: -- general database structure
7828f877c8 2010-08-07 2: -- table to hold all rules
7828f877c8 2010-08-07 3: CREATE TABLE rules (
7828f877c8 2010-08-07 4: netmask cidr NOT NULL,
7828f877c8 2010-08-07 5: redirect_url text DEFAULT 'about::blank'::text NOT NULL,
7828f877c8 2010-08-07 6: from_weekday smallint DEFAULT 0 NOT NULL,
7828f877c8 2010-08-07 7: to_weekday smallint DEFAULT 6 NOT NULL,
7828f877c8 2010-08-07 8: from_time time without time zone DEFAULT '00:00:00'::time without time zone NOT NULL,
7828f877c8 2010-08-07 9: to_time time without time zone DEFAULT '23:59:59'::time without time zone NOT NULL,
7828f877c8 2010-08-07 10: id_tag smallint NOT NULL
7828f877c8 2010-08-07 11: );
7828f877c8 2010-08-07 12:
7828f877c8 2010-08-07 13: ALTER TABLE ONLY rules
7828f877c8 2010-08-07 14: ADD CONSTRAINT rules_tag_f FOREIGN KEY (id_tag) REFERENCES tag(id_tag) MATCH FULL
7828f877c8 2010-08-07 15: ON UPDATE RESTRICT ON DELETE RESTRICT DEFERRABLE INITIALLY DEFERRED;
7828f877c8 2010-08-07 16:
7828f877c8 2010-08-07 17: -- table to hold site arrays
7828f877c8 2010-08-07 18: CREATE TABLE site (
7828f877c8 2010-08-07 19: id_site serial,
7828f877c8 2010-08-07 20: site text[] NOT NULL
7828f877c8 2010-08-07 21: );
7828f877c8 2010-08-07 22:
7828f877c8 2010-08-07 23: ALTER TABLE ONLY site
7828f877c8 2010-08-07 24: ADD CONSTRAINT site_pkey PRIMARY KEY (id_site);
7828f877c8 2010-08-07 25:
7828f877c8 2010-08-07 26: CREATE UNIQUE INDEX site_u ON site (usort(site));
7828f877c8 2010-08-07 27:
7828f877c8 2010-08-07 28: CREATE INDEX site_g ON site USING gin (site);
7828f877c8 2010-08-07 29:
7828f877c8 2010-08-07 30: -- table to hold tag combinations
7828f877c8 2010-08-07 31: CREATE TABLE tag (
7828f877c8 2010-08-07 32: id_tag serial,
7828f877c8 2010-08-07 33: tag text[] NOT NULL
7828f877c8 2010-08-07 34: );
7828f877c8 2010-08-07 35:
7828f877c8 2010-08-07 36: ALTER TABLE ONLY tag
7828f877c8 2010-08-07 37: ADD CONSTRAINT tag_pkey PRIMARY KEY (id_tag);
7828f877c8 2010-08-07 38:
7828f877c8 2010-08-07 39: CREATE UNIQUE INDEX tag_u ON tag (usort(tag));
7828f877c8 2010-08-07 40:
7828f877c8 2010-08-07 41: CREATE INDEX tag_g ON tag USING gin (tag);
7828f877c8 2010-08-07 42:
7828f877c8 2010-08-07 43: -- table to hold tag - site links
7828f877c8 2010-08-07 44: CREATE TABLE urls (
7828f877c8 2010-08-07 45: date_added timestamp without time zone DEFAULT ('now'::text)::timestamp(0) without time zone NOT NULL,
7828f877c8 2010-08-07 46: id_site smallint NOT NULL,
7828f877c8 2010-08-07 47: id_tag smallint NOT NULL,
7828f877c8 2010-08-07 48: regexp text
7828f877c8 2010-08-07 49: );
7828f877c8 2010-08-07 50:
7828f877c8 2010-08-07 51: CREATE UNIQUE INDEX urls_pkey ON urls USING btree (id_site, regexp);
7828f877c8 2010-08-07 52:
7828f877c8 2010-08-07 53: CREATE INDEX urls_id_tag ON urls USING btree (id_tag);
7828f877c8 2010-08-07 54:
7828f877c8 2010-08-07 55: ALTER TABLE ONLY urls
7828f877c8 2010-08-07 56: ADD CONSTRAINT urls_site_f FOREIGN KEY (id_site) REFERENCES site(id_site) MATCH FULL
7828f877c8 2010-08-07 57: ON UPDATE RESTRICT ON DELETE RESTRICT DEFERRABLE INITIALLY DEFERRED;
7828f877c8 2010-08-07 58:
7828f877c8 2010-08-07 59: ALTER TABLE ONLY urls
7828f877c8 2010-08-07 60: ADD CONSTRAINT urls_tag_f FOREIGN KEY (id_tag) REFERENCES tag(id_tag) MATCH FULL
7828f877c8 2010-08-07 61: ON UPDATE RESTRICT ON DELETE RESTRICT DEFERRABLE INITIALLY DEFERRED;
7828f877c8 2010-08-07 62:
7828f877c8 2010-08-07 63: -- rule to join all tables into one to simplify access
7828f877c8 2010-08-07 64: -- automaticall uses current day and time data
7828f877c8 2010-08-07 65: CREATE VIEW site_rule AS
7828f877c8 2010-08-07 66: SELECT a.redirect_url, a.netmask, b.site, b.regexp
7828f877c8 2010-08-07 67: FROM ((
7828f877c8 2010-08-07 68: SELECT rules.redirect_url, tag.tag AS rule_tag, rules.netmask
7828f877c8 2010-08-07 69: FROM rules NATURAL JOIN tag
7828f877c8 2010-08-07 70: WHERE ('now'::text)::time without time zone >= rules.from_time
7828f877c8 2010-08-07 71: AND ('now'::text)::time without time zone <= rules.to_time
7828f877c8 2010-08-07 72: AND date_part('dow'::text, now()) >= (rules.from_weekday)::double precision
7828f877c8 2010-08-07 73: AND date_part('dow'::text, now()) <= (rules.to_weekday)::double precision
7828f877c8 2010-08-07 74: ) a JOIN (
7828f877c8 2010-08-07 75: SELECT site.site, tag.tag AS url_tag, regexp
7828f877c8 2010-08-07 76: FROM urls NATURAL JOIN tag NATURAL JOIN site
7828f877c8 2010-08-07 77: ) b ON (b.url_tag && a.rule_tag));
7828f877c8 2010-08-07 78:
16383de08e 2010-08-07 79: CREATE PROCEDURAL LANGUAGE plpgsql;
16383de08e 2010-08-07 80:
7828f877c8 2010-08-07 81: -- general array sorting and domain processing functions
16383de08e 2010-08-07 82: -- sorts array
16383de08e 2010-08-07 83: CREATE or replace FUNCTION sort(original anyarray) RETURNS anyarray
16383de08e 2010-08-07 84: LANGUAGE sql IMMUTABLE STRICT
16383de08e 2010-08-07 85: AS $_$
16383de08e 2010-08-07 86: select array_agg(item) as result from (select unnest($1) as item order by item) a;
16383de08e 2010-08-07 87: $_$;
16383de08e 2010-08-07 88:
16383de08e 2010-08-07 89: -- sorts array and removes duplicates
16383de08e 2010-08-07 90: CREATE or replace FUNCTION usort(original anyarray) RETURNS anyarray
16383de08e 2010-08-07 91: LANGUAGE sql IMMUTABLE STRICT
16383de08e 2010-08-07 92: AS $_$
16383de08e 2010-08-07 93: select array_agg(item) as result from (select distinct unnest($1) as item order by item) a;
16383de08e 2010-08-07 94: $_$;
16383de08e 2010-08-07 95:
16383de08e 2010-08-07 96: -- transforms domain into ordered array for indexing
16383de08e 2010-08-07 97: CREATE or replace FUNCTION tripdomain(url text) RETURNS text[]
16383de08e 2010-08-07 98: LANGUAGE plpgsql IMMUTABLE STRICT
16383de08e 2010-08-07 99: AS $_$
16383de08e 2010-08-07 100: declare
16383de08e 2010-08-07 101: result text[];
16383de08e 2010-08-07 102: splitted text[];
16383de08e 2010-08-07 103: x integer;
16383de08e 2010-08-07 104: length integer;
16383de08e 2010-08-07 105: begin
16383de08e 2010-08-07 106: splitted := string_to_array($1, '.');
16383de08e 2010-08-07 107: length := array_length(splitted, 1);
16383de08e 2010-08-07 108: x := 1;
16383de08e 2010-08-07 109: loop
16383de08e 2010-08-07 110: exit when splitted[x] is null;
16383de08e 2010-08-07 111: result[x] := splitted[x] || ':' || length - x;
16383de08e 2010-08-07 112: x := x + 1;
16383de08e 2010-08-07 113: end loop;
16383de08e 2010-08-07 114: return result;
16383de08e 2010-08-07 115: end;$_$;
16383de08e 2010-08-07 116:
16383de08e 2010-08-07 117: -- transforms ordered array into domain
16383de08e 2010-08-07 118: create or replace function untrip(site text[]) returns text
16383de08e 2010-08-07 119: language plpgsql immutable strict
16383de08e 2010-08-07 120: as $_$
16383de08e 2010-08-07 121: declare
16383de08e 2010-08-07 122: x integer;
16383de08e 2010-08-07 123: splitted text[];
16383de08e 2010-08-07 124: pair text[];
16383de08e 2010-08-07 125: begin
16383de08e 2010-08-07 126: x := array_length(site, 1);
16383de08e 2010-08-07 127: loop
16383de08e 2010-08-07 128: exit when site[x] is null;
16383de08e 2010-08-07 129: pair := string_to_array(site[x], ':');
16383de08e 2010-08-07 130: splitted[0 - pair[2]::integer] := pair[1];
16383de08e 2010-08-07 131: x := x - 1;
16383de08e 2010-08-07 132: end loop;
16383de08e 2010-08-07 133: return array_to_string(splitted, '.');
16383de08e 2010-08-07 134: end;
16383de08e 2010-08-07 135: $_$;
16383de08e 2010-08-07 136:
7828f877c8 2010-08-07 137: -- functions that works with tables
16383de08e 2010-08-07 138: -- this functions returns id of site
16383de08e 2010-08-07 139: create or replace function get_site(my_site text[]) returns integer
16383de08e 2010-08-07 140: language plpgsql strict
16383de08e 2010-08-07 141: as $$
16383de08e 2010-08-07 142: declare
16383de08e 2010-08-07 143: site_id integer;
16383de08e 2010-08-07 144: begin
16383de08e 2010-08-07 145: select id_site from site where my_site = site into site_id;
16383de08e 2010-08-07 146: if not found then
16383de08e 2010-08-07 147: insert into site (site) values (my_site);
16383de08e 2010-08-07 148: select id_site from site where my_site = site into site_id;
16383de08e 2010-08-07 149: end if;
16383de08e 2010-08-07 150: return site_id;
16383de08e 2010-08-07 151: end;
16383de08e 2010-08-07 152: $$;
16383de08e 2010-08-07 153:
16383de08e 2010-08-07 154: create or replace function get_site(domain text) returns integer
16383de08e 2010-08-07 155: language sql immutable strict
16383de08e 2010-08-07 156: as $$
16383de08e 2010-08-07 157: select get_site(tripdomain($1)) as result;
16383de08e 2010-08-07 158: $$;
16383de08e 2010-08-07 159:
16383de08e 2010-08-07 160: -- this function inserts or updates record with tags to site by site id with regexp
16383de08e 2010-08-07 161: CREATE or replace FUNCTION mark(my_id_site integer, my_id_tag integer, my_regexp text) RETURNS integer
16383de08e 2010-08-07 162: LANGUAGE plpgsql STRICT
16383de08e 2010-08-07 163: AS $$
16383de08e 2010-08-07 164: declare
16383de08e 2010-08-07 165: -- maybe check should be added to make sure supplied site id really exists
16383de08e 2010-08-07 166: my_tag text[];
16383de08e 2010-08-07 167: begin
16383de08e 2010-08-07 168: -- selecting tags site already have and adding new tag to them
16383de08e 2010-08-07 169: -- note that tags should be sorted to eliminate permutations
16383de08e 2010-08-07 170: select coalesce(tag, '{}'::text[]) from urls natural left join tag
16383de08e 2010-08-07 171: where id_site = my_id_site and regexp = my_regexp into my_tag;
16383de08e 2010-08-07 172: if not found then
16383de08e 2010-08-07 173: -- no records found - creating new tag
16383de08e 2010-08-07 174: insert into urls (id_site, id_tag, regexp) values (my_id_site, my_id_tag, my_regexp);
16383de08e 2010-08-07 175: else
16383de08e 2010-08-07 176: -- joining tags
16383de08e 2010-08-07 177: select usort(my_tag || tag) from tag where id_tag = my_id_tag into my_tag;
16383de08e 2010-08-07 178: -- updating existing record
16383de08e 2010-08-07 179: update urls set id_tag = get_tag(my_tag)
16383de08e 2010-08-07 180: where id_site = my_id_site and regexp = my_regexp;
16383de08e 2010-08-07 181: end if;
16383de08e 2010-08-07 182: return my_id_site;
16383de08e 2010-08-07 183: end;
16383de08e 2010-08-07 184: $$;
16383de08e 2010-08-07 185:
16383de08e 2010-08-07 186: -- this function adds tag to site by site id
16383de08e 2010-08-07 187: CREATE or replace FUNCTION mark(my_id_site integer, new_tag text) RETURNS integer
16383de08e 2010-08-07 188: LANGUAGE sql immutable STRICT
16383de08e 2010-08-07 189: AS $$
16383de08e 2010-08-07 190: select mark($1, get_tag(array[$2]), NULL) as result;
16383de08e 2010-08-07 191: $$;
16383de08e 2010-08-07 192:
16383de08e 2010-08-07 193: -- this function adds tag to domain
16383de08e 2010-08-07 194: CREATE or replace FUNCTION mark(domain text, new_tag text) RETURNS integer
16383de08e 2010-08-07 195: LANGUAGE sql immutable STRICT
16383de08e 2010-08-07 196: AS $$
16383de08e 2010-08-07 197: select mark(get_site($1), get_tag(array[$2]), NULL) as result;
16383de08e 2010-08-07 198: $$;
16383de08e 2010-08-07 199:
16383de08e 2010-08-07 200: -- this function sets tags for site without regexp
16383de08e 2010-08-07 201: CREATE or replace FUNCTION set(my_id_site integer, my_id_tag integer) RETURNS integer
16383de08e 2010-08-07 202: LANGUAGE sql STRICT
16383de08e 2010-08-07 203: AS $$
16383de08e 2010-08-07 204: delete from urls where $1 = id_site and regexp is NULL;
16383de08e 2010-08-07 205: insert into urls (id_site, id_tag) values ($1, $2);
16383de08e 2010-08-07 206: select $1;
16383de08e 2010-08-07 207: $$;
16383de08e 2010-08-07 208:
16383de08e 2010-08-07 209: -- this function sets tags for site/regexp pair
16383de08e 2010-08-07 210: CREATE or replace FUNCTION set(my_id_site integer, my_id_tag integer, my_regexp text) RETURNS integer
16383de08e 2010-08-07 211: LANGUAGE sql STRICT
16383de08e 2010-08-07 212: AS $$
16383de08e 2010-08-07 213: delete from urls where $1 = id_site and $3 = regexp;
16383de08e 2010-08-07 214: insert into urls (id_site, id_tag, regexp) values ($1, $2, $3);
16383de08e 2010-08-07 215: select $1;
16383de08e 2010-08-07 216: $$;
16383de08e 2010-08-07 217:
16383de08e 2010-08-07 218: -- this function stores new data for site/regexp pair
16383de08e 2010-08-07 219: create or replace function set(domain text, tags text, regexp text) returns integer
16383de08e 2010-08-07 220: language sql immutable strict
16383de08e 2010-08-07 221: as $$
16383de08e 2010-08-07 222: select set(get_site($1), get_tag($2::text[]), $3);
16383de08e 2010-08-07 223: $$;
16383de08e 2010-08-07 224:
16383de08e 2010-08-07 225: -- this function stores new data for site/regexp pair
16383de08e 2010-08-07 226: create or replace function set(domain text, tags text) returns integer
16383de08e 2010-08-07 227: language sql immutable strict
16383de08e 2010-08-07 228: as $$
16383de08e 2010-08-07 229: select set(get_site($1), get_tag($2::text[]));
16383de08e 2010-08-07 230: $$;
16383de08e 2010-08-07 231:
16383de08e 2010-08-07 232: -- this function returns id of tag array
16383de08e 2010-08-07 233: create or replace function get_tag(my_tag text[]) returns integer
16383de08e 2010-08-07 234: language plpgsql strict
16383de08e 2010-08-07 235: as $$
16383de08e 2010-08-07 236: declare
16383de08e 2010-08-07 237: tag_id integer;
16383de08e 2010-08-07 238: begin
16383de08e 2010-08-07 239: select id_tag from tag where usort(my_tag) = tag into tag_id;
16383de08e 2010-08-07 240: if not found then
16383de08e 2010-08-07 241: insert into tag (tag) values (usort(my_tag));
16383de08e 2010-08-07 242: select id_tag from tag where usort(my_tag) = tag into tag_id;
16383de08e 2010-08-07 243: end if;
16383de08e 2010-08-07 244: return tag_id;
16383de08e 2010-08-07 245: end;
16383de08e 2010-08-07 246: $$;