Project

General

Profile

1 5829 aaronmk
/* To get the place trigger, replace taxonlabel with place and remove references
2
to matched_label_id. */
3 1561 aaronmk
4 5549 aaronmk
----- Functions
5 1558 aaronmk
6 5829 aaronmk
CREATE OR REPLACE FUNCTION taxonlabel_update_ancestors(new taxonlabel, parent_id_ integer, old_parent_id integer DEFAULT NULL::integer)
7 5549 aaronmk
  RETURNS void AS
8 1558 aaronmk
$BODY$
9
BEGIN
10 5549 aaronmk
    IF parent_id_ IS DISTINCT FROM old_parent_id THEN
11
        DECLARE
12
            -- These include the parent itself
13
            old_ancestors integer[] := (
14 5829 aaronmk
                SELECT array_agg(ancestor_id) FROM taxonlabel_relationship
15
                WHERE descendant_id = old_parent_id
16 5549 aaronmk
            );
17
            new_ancestors integer[] := (
18 5829 aaronmk
                SELECT array_agg(ancestor_id) FROM taxonlabel_relationship
19
                WHERE descendant_id = parent_id_
20 5549 aaronmk
            );
21 5829 aaronmk
            descendant_id_ taxonlabel_relationship.descendant_id%TYPE;
22
            ancestor_id_ taxonlabel_relationship.ancestor_id%TYPE;
23 5549 aaronmk
        BEGIN
24 5829 aaronmk
            FOR descendant_id_ IN -- also includes self
25
                SELECT descendant_id
26
                FROM taxonlabel_relationship
27
                WHERE ancestor_id = new.taxonlabel_id
28 5549 aaronmk
            LOOP
29
                -- Delete old parent's ancestors
30 5829 aaronmk
                DELETE FROM taxonlabel_relationship
31
                WHERE descendant_id = descendant_id_
32 5549 aaronmk
                AND ancestor_id = ANY (old_ancestors)
33
                ;
34
35
                -- Add new parent's ancestors
36 5829 aaronmk
                FOR ancestor_id_ IN
37
                    SELECT unnest(new_ancestors)
38
                LOOP
39
                    BEGIN
40
                        INSERT INTO taxonlabel_relationship
41
                        (descendant_id, ancestor_id)
42
                        SELECT descendant_id_, ancestor_id_
43
                        ;
44
                    EXCEPTION
45
                        WHEN unique_violation THEN
46
                            RAISE WARNING '%', SQLERRM;
47
                    END;
48
                END LOOP;
49 5549 aaronmk
            END LOOP;
50
        END;
51 1558 aaronmk
    END IF;
52 1559 aaronmk
53 5549 aaronmk
    /* Note: We don't need an ON DELETE trigger to update the descendants'
54 5551 aaronmk
    ancestors when a node is deleted, because the
55 5829 aaronmk
    taxonlabel_relationship.ancestor_id foreign key is ON DELETE CASCADE. */
56 5549 aaronmk
END;
57
$BODY$
58
  LANGUAGE plpgsql VOLATILE
59
  COST 100;
60
61 5829 aaronmk
CREATE OR REPLACE FUNCTION taxonlabel_update_ancestors_on_insert()
62 5549 aaronmk
  RETURNS trigger AS
63
$BODY$
64
BEGIN
65
    /* Add "ancestor" for this node. This is useful for queries, because you
66
    don't have to separately test if the leaf node is the one you're looking
67
    for, in addition to that leaf node's ancestors. */
68 1559 aaronmk
    INSERT
69 5829 aaronmk
    INTO taxonlabel_relationship
70
    (descendant_id, ancestor_id)
71
    VALUES (new.taxonlabel_id, new.taxonlabel_id)
72 1559 aaronmk
    ;
73
74 5829 aaronmk
    PERFORM taxonlabel_update_ancestors(new, new.parent_id);
75
    PERFORM taxonlabel_update_ancestors(new,
76
        NULLIF(new.matched_label_id, new.taxonlabel_id));
77 1559 aaronmk
78 5549 aaronmk
    RETURN new;
79
END;
80
$BODY$
81
  LANGUAGE plpgsql VOLATILE
82
  COST 100;
83
84 5829 aaronmk
CREATE OR REPLACE FUNCTION taxonlabel_update_ancestors_on_update()
85 5549 aaronmk
  RETURNS trigger AS
86
$BODY$
87
BEGIN
88 5829 aaronmk
    PERFORM taxonlabel_update_ancestors(new, new.parent_id, old.parent_id);
89
    PERFORM taxonlabel_update_ancestors(new,
90
        NULLIF(new.matched_label_id, new.taxonlabel_id),
91
        NULLIF(old.matched_label_id, old.taxonlabel_id));
92 1559 aaronmk
93 1558 aaronmk
    RETURN new;
94
END;
95
$BODY$
96
  LANGUAGE plpgsql VOLATILE
97
  COST 100;
98
99
----- Ancestors table
100
101 5829 aaronmk
CREATE TABLE taxonlabel_relationship
102 1558 aaronmk
(
103 5829 aaronmk
  descendant_id integer NOT NULL,
104 1558 aaronmk
  ancestor_id integer NOT NULL,
105 5829 aaronmk
  relationship relationship NOT NULL DEFAULT 'is included in'::relationship, -- The type of relationship.
106
  CONSTRAINT taxonlabel_relationship_pkey PRIMARY KEY (descendant_id , ancestor_id ),
107
  CONSTRAINT taxonlabel_relationship_ancestor_id_fkey FOREIGN KEY (ancestor_id)
108
      REFERENCES taxonlabel (taxonlabel_id) MATCH SIMPLE
109 1558 aaronmk
      ON UPDATE CASCADE ON DELETE CASCADE,
110 5829 aaronmk
  CONSTRAINT taxonlabel_relationship_descendant_id_fkey FOREIGN KEY (descendant_id)
111
      REFERENCES taxonlabel (taxonlabel_id) MATCH SIMPLE
112 1558 aaronmk
      ON UPDATE CASCADE ON DELETE CASCADE
113
)
114
WITH (
115
  OIDS=FALSE
116
);
117 5829 aaronmk
ALTER TABLE taxonlabel_relationship
118
  OWNER TO bien;
119
COMMENT ON TABLE taxonlabel_relationship
120
  IS 'Stores the accepted ancestors of a taxonlabel. Auto-populated, so should not be manually modified.';
121
COMMENT ON COLUMN taxonlabel_relationship.relationship IS 'The type of relationship.';
122 1558 aaronmk
123 5829 aaronmk
CREATE INDEX taxonlabel_relationship_descendants
124
  ON taxonlabel_relationship
125 5549 aaronmk
  USING btree
126 5829 aaronmk
  (ancestor_id , descendant_id );
127 1558 aaronmk
128 5549 aaronmk
----- Triggers
129
130 5829 aaronmk
CREATE TRIGGER taxonlabel_update_ancestors_on_insert
131 5549 aaronmk
  AFTER INSERT
132 5829 aaronmk
  ON taxonlabel
133 1558 aaronmk
  FOR EACH ROW
134 5829 aaronmk
  EXECUTE PROCEDURE taxonlabel_update_ancestors_on_insert();
135 5549 aaronmk
136 5829 aaronmk
CREATE TRIGGER taxonlabel_update_ancestors_on_update
137 5549 aaronmk
  AFTER UPDATE
138 5829 aaronmk
  ON taxonlabel
139 5549 aaronmk
  FOR EACH ROW
140 5829 aaronmk
  EXECUTE PROCEDURE taxonlabel_update_ancestors_on_update();