1
|
/* To get the place trigger, just search and replace taxonconcept with place. */
|
2
|
|
3
|
----- Trigger function
|
4
|
|
5
|
-- Function: taxonconcept_update_ancestors()
|
6
|
|
7
|
-- DROP FUNCTION taxonconcept_update_ancestors();
|
8
|
|
9
|
CREATE OR REPLACE FUNCTION taxonconcept_update_ancestors()
|
10
|
RETURNS trigger AS
|
11
|
$BODY$
|
12
|
BEGIN
|
13
|
-- Delete existing ancestors
|
14
|
DELETE FROM taxonconcept_ancestor
|
15
|
WHERE taxonconcept_id = new.taxonconcept_id;
|
16
|
|
17
|
IF new.parent_id IS NOT NULL THEN
|
18
|
-- Copy parent's ancestors to this node's ancestors
|
19
|
INSERT
|
20
|
INTO taxonconcept_ancestor
|
21
|
(taxonconcept_id, ancestor_id)
|
22
|
SELECT
|
23
|
new.taxonconcept_id, ancestor_id
|
24
|
FROM taxonconcept_ancestor
|
25
|
WHERE taxonconcept_id = new.parent_id
|
26
|
;
|
27
|
END IF;
|
28
|
|
29
|
-- Add "ancestor" for this node
|
30
|
/* This is useful for queries, because you don't have to separately test if
|
31
|
the leaf node is the one you're looking for, in addition to that leaf node's
|
32
|
ancestors. */
|
33
|
INSERT
|
34
|
INTO taxonconcept_ancestor
|
35
|
(taxonconcept_id, ancestor_id)
|
36
|
VALUES (new.taxonconcept_id, new.taxonconcept_id)
|
37
|
;
|
38
|
|
39
|
-- Tell immediate children to update their ancestors lists, which will
|
40
|
-- recursively tell all descendants
|
41
|
UPDATE taxonconcept
|
42
|
SET taxonconcept_id = taxonconcept_id -- need at least one SET statement
|
43
|
-- Add COALESCE() to enable using taxonconcept_unique index for lookup
|
44
|
WHERE COALESCE(parent_id, 2147483647) = new.taxonconcept_id
|
45
|
;
|
46
|
|
47
|
/* Note: We don't need an ON DELETE trigger to update the descendants'
|
48
|
ancestors when a node is deleted, because the taxonconcept.parent_id foreign
|
49
|
key is ON DELETE CASCADE, which just removes all the descendants anyway. */
|
50
|
|
51
|
RETURN new;
|
52
|
END;
|
53
|
$BODY$
|
54
|
LANGUAGE plpgsql VOLATILE
|
55
|
COST 100;
|
56
|
ALTER FUNCTION taxonconcept_update_ancestors()
|
57
|
OWNER TO bien;
|
58
|
|
59
|
----- Ancestors table
|
60
|
|
61
|
-- Table: taxonconcept_ancestor
|
62
|
|
63
|
-- DROP TABLE taxonconcept_ancestor;
|
64
|
|
65
|
CREATE TABLE taxonconcept_ancestor
|
66
|
(
|
67
|
taxonconcept_id integer NOT NULL,
|
68
|
ancestor_id integer NOT NULL,
|
69
|
CONSTRAINT taxonconcept_ancestor_pkey PRIMARY KEY (taxonconcept_id , ancestor_id ),
|
70
|
CONSTRAINT taxonconcept_ancestor_ancestor_id_fkey FOREIGN KEY (ancestor_id)
|
71
|
REFERENCES taxonconcept (taxonconcept_id) MATCH SIMPLE
|
72
|
ON UPDATE CASCADE ON DELETE CASCADE,
|
73
|
CONSTRAINT taxonconcept_ancestor_taxonconcept_id_fkey FOREIGN KEY (taxonconcept_id)
|
74
|
REFERENCES taxonconcept (taxonconcept_id) MATCH SIMPLE
|
75
|
ON UPDATE CASCADE ON DELETE CASCADE
|
76
|
)
|
77
|
WITH (
|
78
|
OIDS=FALSE
|
79
|
);
|
80
|
ALTER TABLE taxonconcept_ancestor
|
81
|
OWNER TO bien;
|
82
|
|
83
|
----- Trigger
|
84
|
|
85
|
-- Trigger: taxonconcept_update_ancestors on taxonconcept
|
86
|
|
87
|
-- DROP TRIGGER taxonconcept_update_ancestors ON taxonconcept;
|
88
|
|
89
|
CREATE TRIGGER taxonconcept_update_ancestors
|
90
|
AFTER INSERT OR UPDATE
|
91
|
ON taxonconcept
|
92
|
FOR EACH ROW
|
93
|
EXECUTE PROCEDURE taxonconcept_update_ancestors();
|