1------------------------------------------------------------------------------
2-- Database upgrade to 2.0 version
3--
4-- Use:
5--	- psql -f upgrade.sql dns
6--
7------------------------------------------------------------------------------
8
9CREATE USER detecteq ;
10-- ALTER USER detecteq UNENCRYPTED PASSWORD 'XXXXXX' ;
11
12------------------------------------------------------------------------------
13-- new schemas
14------------------------------------------------------------------------------
15
16CREATE SCHEMA global ;
17CREATE SCHEMA dns ;
18CREATE SCHEMA topo ;
19CREATE SCHEMA pgauth ;
20
21GRANT USAGE  ON SCHEMA global, dns, topo, pgauth TO pda, jean, dns ;
22GRANT USAGE  ON SCHEMA         dns, topo         TO                 detecteq ;
23GRANT CREATE ON SCHEMA global, dns, topo, pgauth TO pda, jean ;
24
25ALTER TABLE config  SET SCHEMA global ;
26ALTER TABLE corresp SET SCHEMA global ;
27ALTER TABLE groupe  SET SCHEMA global ;
28ALTER TABLE log     SET SCHEMA global ;
29
30ALTER TABLE communaute    SET SCHEMA dns ;
31ALTER TABLE dhcp          SET SCHEMA dns ;
32ALTER TABLE dhcpprofil    SET SCHEMA dns ;
33ALTER TABLE dhcprange     SET SCHEMA dns ;
34ALTER TABLE domaine       SET SCHEMA dns ;
35ALTER TABLE dr_dhcpprofil SET SCHEMA dns ;
36ALTER TABLE dr_dom        SET SCHEMA dns ;
37ALTER TABLE dr_ip         SET SCHEMA dns ;
38ALTER TABLE dr_mbox       SET SCHEMA dns ;
39ALTER TABLE dr_reseau     SET SCHEMA dns ;
40ALTER TABLE etablissement SET SCHEMA dns ;
41ALTER TABLE hinfo         SET SCHEMA dns ;
42ALTER TABLE relais_dom    SET SCHEMA dns ;
43ALTER TABLE reseau        SET SCHEMA dns ;
44ALTER TABLE role_mail     SET SCHEMA dns ;
45ALTER TABLE role_web      SET SCHEMA dns ;
46ALTER TABLE rr            SET SCHEMA dns ;
47ALTER TABLE rr_cname      SET SCHEMA dns ;
48ALTER TABLE rr_ip         SET SCHEMA dns ;
49ALTER TABLE rr_mx         SET SCHEMA dns ;
50ALTER TABLE zone          SET SCHEMA dns ;
51ALTER TABLE zone_normale  SET SCHEMA dns ;
52ALTER TABLE zone_reverse4 SET SCHEMA dns ;
53ALTER TABLE zone_reverse6 SET SCHEMA dns ;
54
55ALTER SEQUENCE seq_communaute    SET SCHEMA dns ;
56ALTER SEQUENCE seq_corresp       SET SCHEMA dns ;
57ALTER SEQUENCE seq_dhcpprofil    SET SCHEMA dns ;
58ALTER SEQUENCE seq_dhcprange     SET SCHEMA dns ;
59ALTER SEQUENCE seq_domaine       SET SCHEMA dns ;
60ALTER SEQUENCE seq_etablissement SET SCHEMA dns ;
61ALTER SEQUENCE seq_groupe        SET SCHEMA dns ;
62ALTER SEQUENCE seq_hinfo         SET SCHEMA dns ;
63ALTER SEQUENCE seq_reseau        SET SCHEMA dns ;
64ALTER SEQUENCE seq_rr            SET SCHEMA dns ;
65ALTER SEQUENCE seq_zone          SET SCHEMA dns ;
66
67------------------------------------------------------------------------------
68-- Schema
69------------------------------------------------------------------------------
70
71GRANT SELECT ON dns.rr, dns.rr_ip, dns.domaine TO detecteq ;
72
73------------------------------------------------------------------------------
74-- Group permission to access the MAC module
75------------------------------------------------------------------------------
76
77ALTER TABLE global.groupe
78    ADD COLUMN droitmac INT DEFAULT 0
79    ;
80
81UPDATE global.groupe SET droitmac = 0 ;
82
83------------------------------------------------------------------------------
84-- Modified equipement spool
85------------------------------------------------------------------------------
86
87CREATE TABLE topo.modeq (
88	eq		TEXT,		-- fully qualified equipement name
89	date		TIMESTAMP (0)	-- detection date
90			    WITHOUT TIME ZONE
91			    DEFAULT CURRENT_TIMESTAMP,
92	login		TEXT,		-- detected user
93	processed	INT DEFAULT 0,
94) ;
95
96CREATE INDEX modeq_index ON topo.modeq (eq) ;
97
98------------------------------------------------------------------------------
99-- Interface change request spool
100------------------------------------------------------------------------------
101
102CREATE TABLE topo.ifchanges (
103	login		TEXT,		-- requesting user
104	reqdate		TIMESTAMP (0)	-- request date
105			    WITHOUT TIME ZONE
106			    DEFAULT CURRENT_TIMESTAMP,
107	idrr		INT,		-- equipement id
108	iface		TEXT,		-- interface name
109	ifdesc		TEXT,		-- interface description
110	ethervlan	INT,		-- access vlan id
111	voicevlan	INT,		-- voice vlan id
112	processed	INT DEFAULT 0,	-- modification processed
113	moddate		TIMESTAMP (0)	-- modification (or last attempt) date
114			    WITHOUT TIME ZONE,
115	modlog		TEXT,		-- modification (or last attempt) log
116	FOREIGN KEY (idrr) REFERENCES dns.rr (idrr),
117	PRIMARY KEY (idrr, reqdate, iface)
118) ;
119
120------------------------------------------------------------------------------
121-- Last rancid run
122------------------------------------------------------------------------------
123
124CREATE TABLE topo.lastrun (
125	date		TIMESTAMP (0)	-- detection date
126			    WITHOUT TIME ZONE
127) ;
128
129-- insert an empty value to bootstrap the full rancid run
130INSERT INTO topo.lastrun (date) VALUES (NULL) ;
131
132------------------------------------------------------------------------------
133-- Keepstate events
134------------------------------------------------------------------------------
135
136CREATE TABLE topo.keepstate (
137    type	TEXT,		-- "rancid", "anaconf"
138    message	TEXT,		-- last message
139    date	TIMESTAMP (0)	-- first occurrence of this message
140			WITHOUT TIME ZONE
141			DEFAULT CURRENT_TIMESTAMP,
142
143    PRIMARY KEY (type)
144) ;
145
146------------------------------------------------------------------------------
147-- Users to ignore : don't log any event in the modified equipement spool
148-- for these users because we know they have only a read-only access to the
149-- equipements
150------------------------------------------------------------------------------
151
152CREATE TABLE topo.ignoreequsers (
153	login		TEXT UNIQUE NOT NULL	-- user login
154) ;
155
156INSERT INTO topo.ignoreequsers VALUES ('conf') ;
157
158------------------------------------------------------------------------------
159-- Access rights to equipements
160------------------------------------------------------------------------------
161
162CREATE TABLE topo.dr_eq (
163    idgrp	INT,		-- group upon which this access right applies
164    rw		INT,		-- 0 : read, 1 : write
165    pattern	TEXT NOT NULL,	-- regular expression
166    allow_deny	INT,		-- 1 = allow, 0 = deny
167
168    FOREIGN KEY (idgrp) REFERENCES global.groupe (idgrp)
169) ;
170
171------------------------------------------------------------------------------
172-- Sensor definition
173------------------------------------------------------------------------------
174
175-- type trafic
176--	iface = iface[.vlan]
177--	param = NULL
178-- type number of assoc wifi
179--	iface = iface
180--	ssid
181-- type number of auth wifi
182--	iface = iface
183--	param = ssid
184-- type broadcast traffic
185--	iface = iface[.vlan]
186--	param = NULL
187-- type multicast traffic
188--	iface = iface[.vlan]
189--	param = NULL
190
191CREATE TABLE topo.sensor (
192    id		TEXT,		-- M1234
193    type	TEXT,		-- trafic, nbassocwifi, nbauthwifi, etc.
194    eq		TEXT,		-- fqdn
195    comm	TEXT,		-- snmp communuity
196    iface	TEXT,
197    param	TEXT,
198    lastmod	TIMESTAMP (0)	-- last modification date
199		    WITHOUT TIME ZONE
200		    DEFAULT CURRENT_TIMESTAMP,
201    lastseen	TIMESTAMP (0)	-- last detection date
202		    WITHOUT TIME ZONE
203		    DEFAULT CURRENT_TIMESTAMP,
204
205    PRIMARY KEY (id)
206) ;
207
208
209------------------------------------------------------------------------------
210-- Topod file monitor
211------------------------------------------------------------------------------
212
213CREATE TABLE topo.filemonitor (
214	path	TEXT,		-- path to file or directory
215	date	TIMESTAMP (0)	-- last modification date
216			    WITHOUT TIME ZONE
217			    DEFAULT CURRENT_TIMESTAMP,
218
219	PRIMARY KEY (path)
220) ;
221
222------------------------------------------------------------------------------
223-- Topo programs result cache
224------------------------------------------------------------------------------
225
226CREATE TABLE topo.cache (
227	key	    TEXT,		-- hash key
228	command	    TEXT,		-- command called with arguments
229	file	    TEXT,		-- file containing cached command output
230	hit	    INTEGER,		-- number of calls for this entry
231	runtime	    INTEGER,		-- time taken for last command execution
232	lastread    TIMESTAMP		-- last time the entry was read
233		    WITHOUT TIME ZONE,
234	lastrun	    TIMESTAMP		-- last time the entry was written
235		    WITHOUT TIME ZONE,
236	PRIMARY KEY (key)
237) ;
238
239------------------------------------------------------------------------------
240-- Vlan table
241------------------------------------------------------------------------------
242
243CREATE TABLE topo.vlan (
244	vlanid	INT,		-- 1..4095
245	descr	TEXT,		-- description
246	voip	INT DEFAULT 0,	-- 1 if VoIP vlan, 0 if standard vlan
247
248	PRIMARY KEY (vlanid)
249) ;
250
251COPY topo.vlan (vlanid, descr) FROM stdin;
2521	default
253\.
254
255CREATE OR REPLACE FUNCTION modif_vlan () RETURNS trigger AS $$
256    BEGIN
257	INSERT INTO topo.modeq (eq) VALUES ('_vlan') ;
258	RETURN NEW ;
259    END ;
260    $$ LANGUAGE 'plpgsql' ;
261
262CREATE TRIGGER tr_mod_vlan
263    AFTER INSERT OR UPDATE OR DELETE
264    ON topo.vlan
265    FOR EACH ROW
266    EXECUTE PROCEDURE modif_vlan () ;
267
268------------------------------------------------------------------------------
269-- Equipment types and equipment list to create rancid router.db file
270------------------------------------------------------------------------------
271
272CREATE SEQUENCE topo.seq_eqtype START 1 ;
273
274CREATE TABLE topo.eqtype (
275    idtype	INTEGER		-- type id
276	DEFAULT NEXTVAL ('topo.seq_eqtype'),
277    type	TEXT,		-- cisco, hp, juniper, etc.
278
279    UNIQUE (type),
280    PRIMARY KEY (idtype)
281) ;
282
283CREATE SEQUENCE topo.seq_eq START 1 ;
284
285CREATE TABLE topo.eq (
286    ideq	INTEGER		-- equipment id
287	DEFAULT NEXTVAL ('topo.seq_eq'),
288    eq		TEXT,		-- fqdn
289    idtype	INTEGER,
290    up		INTEGER,	-- 1 : up, 0 : 0
291
292    FOREIGN KEY (idtype) REFERENCES topo.eqtype (idtype),
293    UNIQUE (eq),
294    PRIMARY KEY (ideq)
295) ;
296
297COPY topo.eqtype (type) FROM stdin;
298cisco
299juniper
300hp
301\.
302
303CREATE OR REPLACE FUNCTION modif_routerdb () RETURNS trigger AS $$
304    BEGIN
305	INSERT INTO topo.modeq (eq) VALUES ('_routerdb') ;
306	RETURN NEW ;
307    END ;
308    $$ LANGUAGE 'plpgsql' ;
309
310CREATE TRIGGER tr_mod_eq
311    AFTER INSERT OR UPDATE OR DELETE
312    ON topo.eq
313    FOR EACH ROW
314    EXECUTE PROCEDURE modif_routerdb () ;
315
316------------------------------------------------------------------------------
317-- pgauth tables
318------------------------------------------------------------------------------
319
320CREATE TABLE pgauth.user (
321    login	TEXT,		-- login name
322    password	TEXT,		-- crypted password
323    nom		TEXT,		-- name
324    prenom	TEXT,		-- first name
325    mel		TEXT,		-- mail
326    tel		TEXT,		-- phone number
327    mobile	TEXT,		-- mobile phone number
328    fax		TEXT,		-- facsimile number
329    adr		TEXT,		-- address
330
331    -- fields managed by a trigger function
332    phnom	TEXT,		-- phonetical name
333    phprenom	TEXT,		-- phonetical first name
334
335    PRIMARY KEY (login)
336) ;
337
338CREATE TABLE pgauth.realm (
339    realm	TEXT,		-- realm name
340    descr	TEXT,		-- description
341    admin	INT DEFAULT 0,	-- 1 if admin
342
343    PRIMARY KEY (realm)
344) ;
345
346CREATE TABLE pgauth.member (
347    login	TEXT,		-- login name
348    realm	TEXT,		-- realm for this user
349
350    FOREIGN KEY (login) REFERENCES pgauth.user (login),
351    FOREIGN KEY (realm) REFERENCES pgauth.realm (realm),
352    PRIMARY KEY (login, realm)
353) ;
354
355------------------------------------------------------------------------------
356-- Authorizations
357------------------------------------------------------------------------------
358
359GRANT SELECT ON topo.ignoreequsers, dns.rr, dns.rr_ip, dns.domaine TO detecteq ;
360GRANT INSERT ON topo.modeq TO detecteq ;
361
362GRANT ALL
363    ON topo.modeq, topo.ifchanges, topo.lastrun, topo.keepstate, topo.dr_eq,
364	topo.sensor, topo.filemonitor, topo.cache, topo.vlan,
365	topo.seq_eqtype, topo.seq_eq, topo.eqtype, topo.eq
366	pgauth.user, pgauth.realm, pgauth.member
367    TO dns, pda, jean ;
368
369------------------------------------------------------------------------------
370-- New configuration values
371------------------------------------------------------------------------------
372
373COPY global.config (clef, valeur) FROM stdin;
374topoactive	0
375topofrom	nobody.topo@unistra.fr
376topoto	di-infra-expl-res@unistra.fr pda@unistra.fr
377topographddelay	5
378toposendddelay	5
379topomaxstatus	100
380sensorexpire	30
381dhcpdefdomain	example.com
382dhcpdefdnslist	1.2.3.4,5.6.7.8
383modeqexpire	30
384ifchangeexpire	30
385fullrancidmin	2
386fullrancidmax	4
387\.
388
389------------------------------------------------------------------------------
390-- Adapt functions to new schemas
391------------------------------------------------------------------------------
392
393CREATE OR REPLACE FUNCTION markcidr (reseau CIDR, lim INTEGER, grp INTEGER)
394    RETURNS void AS $$
395    DECLARE
396	min INET ;
397	max INET ;
398	a INET ;
399    BEGIN
400	min := INET (HOST (reseau)) ;
401	max := INET (HOST (BROADCAST (reseau))) ;
402
403	IF max - min - 2 > lim THEN
404	    RAISE EXCEPTION 'Too many addresses' ;
405	END IF ;
406
407	-- All this exception machinery is here since we can't use :
408	--    DROP TABLE IF EXISTS allip ;
409	-- It raises a notice exception, which prevents
410	-- script "ajout" to function
411	BEGIN
412	    DROP TABLE allip ;
413	EXCEPTION
414	    WHEN OTHERS THEN -- nothing
415	END ;
416
417	CREATE TEMPORARY TABLE allip (
418	    adr INET,
419	    avail INTEGER,
420		-- 0 : unavailable (broadcast addr, no right on addr, etc.)
421		-- 1 : not declared and not in a dhcp range
422		-- 2 : declared and not in a dhcp range
423		-- 3 : not declared and in a dhcp range
424		-- 4 : declared and in a dhcp range
425	    fqdn TEXT			-- if 2 or 4, then fqdn else NULL
426	) ;
427
428	a := min ;
429	WHILE a <= max LOOP
430	    INSERT INTO allip VALUES (a, 1) ;
431	    a := a + 1 ;
432	END LOOP ;
433
434	UPDATE allip
435	    SET fqdn = rr.nom || '.' || domaine.nom,
436		avail = 2
437	    FROM dns.rr_ip, dns.rr, dns.domaine
438	    WHERE allip.adr = rr_ip.adr
439		AND rr_ip.idrr = rr.idrr
440		AND rr.iddom = domaine.iddom
441		;
442
443	UPDATE allip
444	    SET avail = CASE
445			    WHEN avail = 1 THEN 3
446			    WHEN avail = 2 THEN 4
447			END
448	    FROM dns.dhcprange
449	    WHERE (avail = 1 OR avail = 2)
450		AND adr >= dhcprange.min
451		AND adr <= dhcprange.max
452	    ;
453
454	UPDATE allip SET avail = 0
455	    WHERE adr = min OR adr = max OR NOT valide_ip_grp (adr, grp) ;
456
457	RETURN ;
458
459    END ;
460    $$ LANGUAGE plpgsql ;
461
462CREATE OR REPLACE FUNCTION gen_rev4 (INET)
463    RETURNS INTEGER AS $$
464    BEGIN
465	UPDATE dns.zone_reverse4 SET generer = 1 WHERE $1 <<= selection ;
466	RETURN 1 ;
467    END ;
468    $$ LANGUAGE 'plpgsql' ;
469
470-- appel� lors de la modification d'une adresse IPv6
471CREATE OR REPLACE FUNCTION gen_rev6 (INET)
472    RETURNS INTEGER AS $$
473    BEGIN
474	UPDATE dns.zone_reverse6 SET generer = 1 WHERE $1 <<= selection ;
475	RETURN 1 ;
476    END ;
477    $$ LANGUAGE 'plpgsql' ;
478
479-- ID du RR
480CREATE OR REPLACE FUNCTION gen_norm_idrr (INTEGER)
481    RETURNS INTEGER AS $$
482    BEGIN
483	UPDATE dns.zone_normale SET generer = 1
484		WHERE selection = (
485			SELECT domaine.nom
486				FROM dns.domaine, dns.rr
487				WHERE rr.idrr = $1 AND rr.iddom = domaine.iddom
488			) ;
489	RETURN 1 ;
490    END ;
491    $$ LANGUAGE 'plpgsql' ;
492
493CREATE OR REPLACE FUNCTION gen_norm_iddom (INTEGER)
494    RETURNS INTEGER AS $$
495    BEGIN
496	UPDATE dns.zone_normale SET generer = 1
497		WHERE selection = (
498			SELECT domaine.nom
499				FROM dns.domaine
500				WHERE domaine.iddom = $1
501			) ;
502	RETURN 1 ;
503    END ;
504    $$ LANGUAGE 'plpgsql' ;
505
506CREATE OR REPLACE FUNCTION modifier_ip ()
507    RETURNS trigger AS $$
508    BEGIN
509	IF TG_OP = 'INSERT'
510	THEN
511	    PERFORM sum (gen_rev4 (NEW.adr)) ;
512	    PERFORM sum (gen_rev6 (NEW.adr)) ;
513	    PERFORM sum (gen_norm_idrr (NEW.idrr)) ;
514
515	    UPDATE dns.dhcp SET generer = 1
516		FROM dns.rr WHERE rr.idrr = NEW.idrr AND rr.mac IS NOT NULL ;
517
518	    UPDATE dns.dhcp SET generer = 1
519		FROM dns.rr WHERE rr.idrr = NEW.idrr AND rr.mac IS NOT NULL ;
520	END IF ;
521
522	IF TG_OP = 'UPDATE'
523	THEN
524	    PERFORM sum (gen_rev4 (NEW.adr)) ;
525	    PERFORM sum (gen_rev4 (OLD.adr)) ;
526	    PERFORM sum (gen_rev6 (NEW.adr)) ;
527	    PERFORM sum (gen_rev6 (OLD.adr)) ;
528	    PERFORM sum (gen_norm_idrr (NEW.idrr)) ;
529	    PERFORM sum (gen_norm_idrr (OLD.idrr)) ;
530
531	    UPDATE dns.dhcp SET generer = 1
532		FROM dns.rr WHERE rr.idrr = OLD.idrr AND rr.mac IS NOT NULL ;
533	    UPDATE dns.dhcp SET generer = 1
534		FROM dns.rr WHERE rr.idrr = NEW.idrr AND rr.mac IS NOT NULL ;
535	END IF ;
536
537	IF TG_OP = 'DELETE'
538	THEN
539	    PERFORM sum (gen_rev4 (OLD.adr)) ;
540	    PERFORM sum (gen_rev6 (OLD.adr)) ;
541	    PERFORM sum (gen_norm_idrr (OLD.idrr)) ;
542
543	    UPDATE dns.dhcp SET generer = 1
544		FROM dns.rr WHERE rr.idrr = OLD.idrr AND rr.mac IS NOT NULL ;
545	END IF ;
546
547	RETURN NEW ;
548    END ;
549    $$ LANGUAGE 'plpgsql' ;
550
551CREATE OR REPLACE FUNCTION modifier_mxcname ()
552    RETURNS trigger AS $$
553    BEGIN
554	IF TG_OP = 'INSERT'
555	THEN
556	    PERFORM sum (gen_norm_idrr (NEW.idrr)) ;
557	END IF ;
558
559	IF TG_OP = 'UPDATE'
560	THEN
561	    PERFORM sum (gen_norm_idrr (NEW.idrr)) ;
562	    PERFORM sum (gen_norm_idrr (OLD.idrr)) ;
563	END IF ;
564
565	IF TG_OP = 'DELETE'
566	THEN
567	    PERFORM sum (gen_norm_idrr (OLD.idrr)) ;
568	END IF ;
569
570	RETURN NEW ;
571    END ;
572    $$ LANGUAGE 'plpgsql' ;
573
574-- modifier le RR et les zones reverses pour toutes les adresses IP
575CREATE OR REPLACE FUNCTION modifier_rr ()
576    RETURNS trigger AS $$
577    BEGIN
578	IF TG_OP = 'INSERT'
579	THEN
580	    PERFORM sum (gen_norm_iddom (NEW.iddom)) ;
581	    PERFORM sum (gen_rev4 (adr)) FROM dns.rr_ip WHERE idrr = NEW.idrr ;
582	    PERFORM sum (gen_rev6 (adr)) FROM dns.rr_ip WHERE idrr = NEW.idrr ;
583
584	    IF NEW.mac IS NOT NULL
585	    THEN
586		UPDATE dns.dhcp SET generer = 1 ;
587	    END IF ;
588	END IF ;
589
590	IF TG_OP = 'UPDATE'
591	THEN
592	    PERFORM sum (gen_norm_iddom (NEW.iddom)) ;
593	    PERFORM sum (gen_rev4 (adr)) FROM dns.rr_ip WHERE idrr = NEW.idrr ;
594	    PERFORM sum (gen_rev6 (adr)) FROM dns.rr_ip WHERE idrr = NEW.idrr ;
595	    PERFORM sum (gen_norm_iddom (OLD.iddom)) ;
596	    PERFORM sum (gen_rev4 (adr)) FROM dns.rr_ip WHERE idrr = OLD.idrr ;
597	    PERFORM sum (gen_rev6 (adr)) FROM dns.rr_ip WHERE idrr = OLD.idrr ;
598
599	    IF OLD.mac IS DISTINCT FROM NEW.mac
600		OR OLD.iddhcpprofil IS DISTINCT FROM NEW.iddhcpprofil
601	    THEN
602		UPDATE dns.dhcp SET generer = 1 ;
603	    END IF ;
604	END IF ;
605
606	IF TG_OP = 'DELETE'
607	THEN
608	    PERFORM sum (gen_norm_iddom (OLD.iddom)) ;
609	    PERFORM sum (gen_rev4 (adr)) FROM dns.rr_ip WHERE idrr = OLD.idrr ;
610	    PERFORM sum (gen_rev6 (adr)) FROM dns.rr_ip WHERE idrr = OLD.idrr ;
611
612	    IF OLD.mac IS NOT NULL
613	    THEN
614		UPDATE dns.dhcp SET generer = 1 ;
615	    END IF ;
616	END IF ;
617
618	RETURN NEW ;
619    END ;
620    $$ LANGUAGE 'plpgsql' ;
621
622CREATE OR REPLACE FUNCTION gen_relais (INTEGER)
623    RETURNS INTEGER AS $$
624    BEGIN
625	UPDATE dns.zone_normale SET generer = 1
626	    WHERE selection = (SELECT nom FROM dns.domaine WHERE iddom = $1) ;
627	RETURN 1 ;
628    END ;
629    $$ LANGUAGE 'plpgsql' ;
630
631CREATE OR REPLACE FUNCTION generer_dhcp ()
632    RETURNS TRIGGER AS $$
633    BEGIN
634	UPDATE dns.dhcp SET generer = 1 ;
635	RETURN NEW ;
636    END ;
637    $$ LANGUAGE 'plpgsql' ;
638
639CREATE OR REPLACE FUNCTION valide_ip_cor (INET, INTEGER)
640    RETURNS BOOLEAN AS $$
641    BEGIN
642	RETURN valide_ip_grp ($1, idgrp) FROM global.corresp WHERE idcor = $2 ;
643    END ;
644    $$ LANGUAGE 'plpgsql' ;
645
646-- arg 1: address to test
647-- arg 2: group id
648CREATE OR REPLACE FUNCTION valide_ip_grp (INET, INTEGER)
649    RETURNS BOOLEAN AS $$
650    BEGIN
651	RETURN ($1 <<= ANY (SELECT adr FROM dns.dr_ip
652				WHERE allow_deny = 1 AND idgrp = $2)
653	    AND NOT $1 <<= ANY (SELECT adr FROM dns.dr_ip
654				WHERE allow_deny = 0 AND idgrp = $2)
655	    ) ;
656    END ;
657    $$ LANGUAGE 'plpgsql' ;
658
659\encoding latin9
660CREATE FUNCTION soundex (TEXT) RETURNS TEXT AS '
661	array set soundexFrenchCode {
662	    a 0 b 1 c 2 d 3 e 0 f 9 g 7 h 0 i 0 j 7 k 2 l 4 m 5
663	    n 5 o 0 p 1 q 2 r 6 s 8 t 3 u 0 v 9 w 9 x 8 y 0 z 8
664	}
665	set accentedFrenchMap {
666	    � e  � e  � e  � e   � E  � E  � E  � E
667	     � a  � a  � a        � A  � A  � A
668	     � i  � i             � I  � I
669	     � o  � o             � O  � O
670	     � u  � u  � u        � U  � U  � U
671	     � ss                 � SS
672	}
673	set key ""
674
675	# Map accented characters
676	set TempIn [string map $accentedFrenchMap $1]
677
678	# Only use alphabetic characters, so strip out all others
679	# also, soundex index uses only lower case chars, so force to lower
680
681	regsub -all {[^a-z]} [string tolower $TempIn] {} TempIn
682	if {[string length $TempIn] == 0} {
683	    return Z000
684	}
685	set last [string index $TempIn 0]
686	set key  [string toupper $last]
687	set last $soundexFrenchCode($last)
688
689	# Scan rest of string, stop at end of string or when the key is
690	# full
691
692	set count    1
693	set MaxIndex [string length $TempIn]
694
695	for {set index 1} {(($count < 4) && ($index < $MaxIndex))} {incr index } {
696	    set chcode $soundexFrenchCode([string index $TempIn $index])
697	    # Fold together adjacent letters sharing the same code
698	    if {![string equal $last $chcode]} {
699		set last $chcode
700		# Ignore code==0 letters except as separators
701		if {$last != 0} then {
702		    set key $key$last
703		    incr count
704		}
705	    }
706	}
707	return [string range ${key}0000 0 3]
708    ' LANGUAGE 'pltcl' WITH (isStrict) ;
709
710CREATE FUNCTION add_soundex () RETURNS TRIGGER AS '
711    BEGIN
712	NEW.phnom    := SOUNDEX (NEW.nom) ;
713	NEW.phprenom := SOUNDEX (NEW.prenom) ;
714	RETURN NEW ;
715    END ;
716    ' LANGUAGE 'plpgsql' ;
717
718CREATE TRIGGER phnom
719    BEFORE INSERT OR UPDATE
720    ON pgauth.user
721    FOR EACH ROW
722    EXECUTE PROCEDURE add_soundex ()
723    ;
724
725-- do not forget to upgrade the zone generation script on the DNS server
726update dns.zone_normale  set prologue=replace(prologue, '%VERSION%', '%ZONEVERSION%') ;
727update dns.zone_reverse4 set prologue=replace(prologue, '%VERSION%', '%ZONEVERSION%') ;
728update dns.zone_reverse6 set prologue=replace(prologue, '%VERSION%', '%ZONEVERSION%') ;
729