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