Revision 3ab10ea9
Von Moritz Bunkus vor mehr als 10 Jahren hinzugefügt
sql/Pg-upgrade2/requirement_spec_delete_trigger_fix.sql | ||
---|---|---|
1 |
-- @tag: requirement_spec_delete_trigger_fix |
|
2 |
-- @description: Fixes für Delete-Trigger bei Pflichtenheften |
|
3 |
-- @depends: requirement_spec_items_update_trigger_fix |
|
4 |
|
|
5 |
-- Trigger for updating time_estimation of function blocks from their |
|
6 |
-- children (not for sections, not for sub function blocks). |
|
7 |
CREATE OR REPLACE FUNCTION update_requirement_spec_item_time_estimation(item_id INTEGER, requirement_spec_id INTEGER) RETURNS BOOLEAN AS $$ |
|
8 |
DECLARE |
|
9 |
item RECORD; |
|
10 |
BEGIN |
|
11 |
IF item_id IS NULL THEN |
|
12 |
RAISE DEBUG 'updateRSIE: item_id IS NULL'; |
|
13 |
RETURN FALSE; |
|
14 |
END IF; |
|
15 |
|
|
16 |
IF EXISTS( |
|
17 |
SELECT * |
|
18 |
FROM trigger_information |
|
19 |
WHERE ((key = 'deleting_requirement_spec_item') AND (value = CAST(item_id AS TEXT))) |
|
20 |
OR ((key = 'deleting_requirement_spec') AND (value = CAST(requirement_spec_id AS TEXT))) |
|
21 |
LIMIT 1 |
|
22 |
) THEN |
|
23 |
RAISE DEBUG 'updateRSIE: item_id % or requirement_spec_id % is about to be deleted; do not update', item_id, requirement_spec_id; |
|
24 |
RETURN FALSE; |
|
25 |
END IF; |
|
26 |
|
|
27 |
SELECT * INTO item FROM requirement_spec_items WHERE id = item_id; |
|
28 |
RAISE DEBUG 'updateRSIE: item_id % item_type %', item_id, item.item_type; |
|
29 |
|
|
30 |
IF (item.item_type = 'sub-function-block') THEN |
|
31 |
-- Don't do anything for sub-function-blocks. |
|
32 |
RAISE DEBUG 'updateRSIE: this is a sub-function-block, not updating.'; |
|
33 |
RETURN FALSE; |
|
34 |
END IF; |
|
35 |
|
|
36 |
RAISE DEBUG 'updateRSIE: will do stuff now'; |
|
37 |
|
|
38 |
UPDATE requirement_spec_items |
|
39 |
SET time_estimation = COALESCE(( |
|
40 |
SELECT SUM(time_estimation) |
|
41 |
FROM requirement_spec_items |
|
42 |
WHERE parent_id = item_id |
|
43 |
), 0) |
|
44 |
WHERE id = item_id; |
|
45 |
|
|
46 |
IF (item.item_type = 'section') THEN |
|
47 |
RAISE DEBUG 'updateRSIE: updating requirement_spec % itself as well.', item.requirement_spec_id; |
|
48 |
UPDATE requirement_specs |
|
49 |
SET time_estimation = COALESCE(( |
|
50 |
SELECT SUM(time_estimation) |
|
51 |
FROM requirement_spec_items |
|
52 |
WHERE (parent_id IS NULL) |
|
53 |
AND (requirement_spec_id = item.requirement_spec_id) |
|
54 |
), 0); |
|
55 |
END IF; |
|
56 |
|
|
57 |
RETURN TRUE; |
|
58 |
END; |
|
59 |
$$ LANGUAGE plpgsql; |
|
60 |
|
|
61 |
CREATE OR REPLACE FUNCTION requirement_spec_item_time_estimation_updater_trigger() RETURNS trigger AS $$ |
|
62 |
DECLARE |
|
63 |
do_new BOOLEAN; |
|
64 |
BEGIN |
|
65 |
RAISE DEBUG 'updateRSITE op %', TG_OP; |
|
66 |
IF ((TG_OP = 'UPDATE') OR (TG_OP = 'DELETE')) THEN |
|
67 |
RAISE DEBUG 'UPDATE trigg op % OLD.id % OLD.parent_id %', TG_OP, OLD.id, OLD.parent_id; |
|
68 |
PERFORM update_requirement_spec_item_time_estimation(OLD.parent_id, OLD.requirement_spec_id); |
|
69 |
RAISE DEBUG 'UPDATE trigg op % END %', TG_OP, OLD.id; |
|
70 |
END IF; |
|
71 |
do_new = FALSE; |
|
72 |
|
|
73 |
IF (TG_OP = 'UPDATE') THEN |
|
74 |
do_new = OLD.parent_id <> NEW.parent_id; |
|
75 |
END IF; |
|
76 |
|
|
77 |
IF (do_new OR (TG_OP = 'INSERT')) THEN |
|
78 |
RAISE DEBUG 'UPDATE trigg op % NEW.id % NEW.parent_id %', TG_OP, NEW.id, NEW.parent_id; |
|
79 |
PERFORM update_requirement_spec_item_time_estimation(NEW.parent_id, NEW.requirement_spec_id); |
|
80 |
RAISE DEBUG 'UPDATE trigg op % END %', TG_OP, NEW.id; |
|
81 |
END IF; |
|
82 |
|
|
83 |
RETURN NULL; |
|
84 |
END; |
|
85 |
$$ LANGUAGE plpgsql; |
|
86 |
|
|
87 |
DROP TRIGGER IF EXISTS update_requirement_spec_item_time_estimation ON requirement_spec_items; |
|
88 |
CREATE TRIGGER update_requirement_spec_item_time_estimation |
|
89 |
AFTER INSERT OR UPDATE OR DELETE ON requirement_spec_items |
|
90 |
FOR EACH ROW EXECUTE PROCEDURE requirement_spec_item_time_estimation_updater_trigger(); |
|
91 |
|
|
92 |
|
|
93 |
-- Trigger for deleting depending stuff if a requirement spec item is deleted. |
|
94 |
CREATE OR REPLACE FUNCTION requirement_spec_item_before_delete_trigger() RETURNS trigger AS $$ |
|
95 |
BEGIN |
|
96 |
RAISE DEBUG 'delete trig RSitem old id %', OLD.id; |
|
97 |
INSERT INTO trigger_information (key, value) VALUES ('deleting_requirement_spec_item', CAST(OLD.id AS TEXT)); |
|
98 |
DELETE FROM requirement_spec_item_dependencies WHERE (depending_item_id = OLD.id) OR (depended_item_id = OLD.id); |
|
99 |
DELETE FROM requirement_spec_items WHERE (parent_id = OLD.id); |
|
100 |
DELETE FROM trigger_information WHERE (key = 'deleting_requirement_spec_item') AND (value = CAST(OLD.id AS TEXT)); |
|
101 |
RAISE DEBUG 'delete trig END %', OLD.id; |
|
102 |
RETURN OLD; |
|
103 |
END; |
|
104 |
$$ LANGUAGE plpgsql; |
|
105 |
|
|
106 |
DROP TRIGGER IF EXISTS delete_requirement_spec_item_dependencies ON requirement_spec_items; |
|
107 |
CREATE TRIGGER delete_requirement_spec_item_dependencies |
|
108 |
BEFORE DELETE ON requirement_spec_items |
|
109 |
FOR EACH ROW EXECUTE PROCEDURE requirement_spec_item_before_delete_trigger(); |
|
110 |
|
|
111 |
|
|
112 |
-- Trigger for deleting depending stuff if a requirement spec is deleted. |
|
113 |
CREATE OR REPLACE FUNCTION requirement_spec_delete_trigger() RETURNS trigger AS $$ |
|
114 |
DECLARE |
|
115 |
tname TEXT; |
|
116 |
BEGIN |
|
117 |
tname := 'tmp_delete_reqspec' || OLD.id; |
|
118 |
|
|
119 |
IF TG_WHEN = 'AFTER' THEN |
|
120 |
RAISE DEBUG 'after trigger on %; deleting from versions', OLD.id; |
|
121 |
EXECUTE 'DELETE FROM requirement_spec_versions ' || |
|
122 |
'WHERE id IN (SELECT version_id FROM ' || tname || ')'; |
|
123 |
|
|
124 |
RAISE DEBUG ' dropping table'; |
|
125 |
EXECUTE 'DROP TABLE ' || tname; |
|
126 |
|
|
127 |
DELETE FROM trigger_information WHERE (key = 'deleting_requirement_spec') AND (value = CAST(OLD.id AS TEXT)); |
|
128 |
|
|
129 |
RETURN OLD; |
|
130 |
END IF; |
|
131 |
|
|
132 |
RAISE DEBUG 'before delete trigger on %', OLD.id; |
|
133 |
|
|
134 |
INSERT INTO trigger_information (key, value) VALUES ('deleting_requirement_spec', CAST(OLD.id AS TEXT)); |
|
135 |
|
|
136 |
EXECUTE 'CREATE TEMPORARY TABLE ' || tname || ' AS ' || |
|
137 |
'SELECT DISTINCT version_id ' || |
|
138 |
'FROM requirement_specs ' || |
|
139 |
'WHERE (version_id IS NOT NULL) ' || |
|
140 |
' AND ((id = ' || OLD.id || ') OR (working_copy_id = ' || OLD.id || '))'; |
|
141 |
|
|
142 |
RAISE DEBUG ' Updating version_id and items for %', OLD.id; |
|
143 |
UPDATE requirement_specs SET version_id = NULL WHERE (id <> OLD.id) AND (working_copy_id = OLD.id); |
|
144 |
UPDATE requirement_spec_items SET item_type = 'section', parent_id = NULL WHERE requirement_spec_id = OLD.id; |
|
145 |
|
|
146 |
RAISE DEBUG ' Deleting stuff for %', OLD.id; |
|
147 |
|
|
148 |
DELETE FROM requirement_spec_text_blocks WHERE (requirement_spec_id = OLD.id); |
|
149 |
DELETE FROM requirement_spec_items WHERE (requirement_spec_id = OLD.id); |
|
150 |
DELETE FROM requirement_specs WHERE (working_copy_id = OLD.id); |
|
151 |
|
|
152 |
RAISE DEBUG ' And we out for %', OLD.id; |
|
153 |
|
|
154 |
RETURN OLD; |
|
155 |
END; |
|
156 |
$$ LANGUAGE plpgsql; |
|
157 |
|
|
158 |
DROP TRIGGER IF EXISTS delete_requirement_spec_dependencies ON requirement_specs; |
|
159 |
CREATE TRIGGER delete_requirement_spec_dependencies |
|
160 |
BEFORE DELETE ON requirement_specs |
|
161 |
FOR EACH ROW EXECUTE PROCEDURE requirement_spec_delete_trigger(); |
|
162 |
|
|
163 |
DROP TRIGGER IF EXISTS after_delete_requirement_spec_dependencies ON requirement_specs; |
|
164 |
CREATE TRIGGER after_delete_requirement_spec_dependencies |
|
165 |
AFTER DELETE ON requirement_specs |
|
166 |
FOR EACH ROW EXECUTE PROCEDURE requirement_spec_delete_trigger(); |
|
167 |
|
|
168 |
DROP FUNCTION IF EXISTS update_requirement_spec_item_time_estimation(item_id INTEGER); |
Auch abrufbar als: Unified diff
Pflichtenhefte: Lösch-Trigger fixen
Wenn ein Pflichtenheft gelöscht wird, darf der Trigger zum Updaten der
Zeitschätzung nicht in das zu löschende Pflichtenheft schreiben --
aufgrund eines unlustigen Bugs in PostgreSQL. Analog zu den
Items. Also verhindern, dass etwas getan wird, wenn das Pflichtenheft
selber gelöscht werden soll.