Merge lp:~cjwatson/launchpad/db-bugsummary-statement-triggers into lp:launchpad/db-devel

Proposed by Colin Watson
Status: Rejected
Rejected by: Colin Watson
Proposed branch: lp:~cjwatson/launchpad/db-bugsummary-statement-triggers
Merge into: lp:launchpad/db-devel
Diff against target: 274 lines (+255/-3)
2 files modified
database/schema/patch-2210-06-0.sql (+251/-0)
database/schema/security.cfg (+4/-3)
To merge this branch: bzr merge lp:~cjwatson/launchpad/db-bugsummary-statement-triggers
Reviewer Review Type Date Requested Status
Stuart Bishop db Pending
Launchpad code reviewers db Pending
Review via email: mp+371297@code.launchpad.net

Commit message

Rewrite BugSummary triggers to be statement-level.

Description of the change

Rewrite the BugSummaryJournal maintenance triggers to make use of the new transition tables provided to AFTER ... FOR EACH STATEMENT triggers as of PostgreSQL 10. Instead of using row-level triggers which accumulate changes in a temporary table and flush it into the journal, we now write directly to the journal at the end of each statement.

There's a considerable amount of complexity here due to transition tables only being visible in the trigger function itself, not in functions that it calls. I used a combination of LATERAL and dynamic commands to minimise the amount of repeated code resulting from this. This does mean that the outermost part of each trigger function's query needs to be replanned each time the trigger runs, but I don't expect that to make a significant performance difference.

The transformations related to bug tags aren't completely obvious. I eliminated summarise_bug and unsummarise_bug from the call chain, as they didn't seem to be pulling their weight. When BugTag is changed, rather than decrementing/incrementing all the BugSummary rows that the changed bugs expand to, it now makes more sense to do so only for the rows relating to the changed tags. This necessitated extending bugsummary_journal_bugtaskflat and friends to take an array of tags, so it now processes all tags on the bug plus NULL when handling BugTaskFlat changes, and only the changed tags when handling BugTag changes.

I can't say for sure whether this will fix the periodic bug update timeouts we've been seeing, since we've never completely got to the bottom of their cause. However, reducing the number of times the trigger functions need to be called and eliminating their use of an explicit temporary table seem likely to improve matters.

To post a comment you must log in.
Revision history for this message
Colin Watson (cjwatson) wrote :

Unmerged revisions

14125. By Colin Watson

Rewrite BugSummary triggers to be statement-level.

Preview Diff

[H/L] Next/Prev Comment, [J/K] Next/Prev File, [N/P] Next/Prev Hunk
=== added file 'database/schema/patch-2210-06-0.sql'
--- database/schema/patch-2210-06-0.sql 1970-01-01 00:00:00 +0000
+++ database/schema/patch-2210-06-0.sql 2019-08-14 14:18:02 +0000
@@ -0,0 +1,251 @@
1-- Copyright 2019 Canonical Ltd. This software is licensed under the
2-- GNU Affero General Public License version 3 (see the file LICENSE).
3
4SET client_min_messages=ERROR;
5
6-- Rewrite the BugSummaryJournal maintenance triggers to make use of the new
7-- transition tables provided to AFTER ... FOR EACH STATEMENT triggers as of
8-- PostgreSQL 10. Instead of using row-level triggers which accumulate
9-- changes in a temporary table and flush it into the journal, we now write
10-- directly to the journal at the end of each statement.
11
12DROP TRIGGER bugtaskflat_maintain_bug_summary ON bugtaskflat;
13DROP TRIGGER bugtag_maintain_bug_summary_before_trigger ON bugtag;
14DROP TRIGGER bugtag_maintain_bug_summary_after_trigger ON bugtag;
15
16-- Similar to the previous bugsummary_tags, but returns an array of tags on
17-- the given bug plus NULL; this can be passed to other functions, and is
18-- suitable for constructing a set of rows to insert into BugSummaryJournal
19-- when handling changes to BugTaskFlat.
20CREATE OR REPLACE FUNCTION bugsummary_tag_names(bug integer)
21 RETURNS text[]
22 LANGUAGE sql STABLE
23 AS $_$
24 SELECT array_agg(tag)
25 FROM (
26 SELECT BugTag.tag FROM BugTag WHERE BugTag.bug = $1
27 UNION ALL
28 SELECT NULL::text
29 ) AS tag;
30$_$;
31
32COMMENT ON FUNCTION bugsummary_tag_names IS
33 'Return an array of the tag names on the given bug, plus NULL; this is suitable for constructing BugSummaryJournal rows when handling changes to BugTaskFlat.';
34
35-- Modify the existing bugsummary_locations to accept an array of tags
36-- rather than looking them up for itself.
37DROP FUNCTION bugsummary_locations;
38CREATE FUNCTION bugsummary_locations(btf_row bugtaskflat, tags text[])
39 RETURNS SETOF bugsummary
40 LANGUAGE plpgsql
41 AS $$
42BEGIN
43 IF btf_row.duplicateof IS NOT NULL THEN
44 RETURN;
45 END IF;
46 RETURN QUERY
47 SELECT
48 CAST(NULL AS integer) AS id,
49 CAST(1 AS integer) AS count,
50 bug_targets.product, bug_targets.productseries,
51 bug_targets.distribution, bug_targets.distroseries,
52 bug_targets.sourcepackagename,
53 bug_viewers.viewed_by, bug_tags.tag, btf_row.status,
54 btf_row.milestone, btf_row.importance,
55 btf_row.latest_patch_uploaded IS NOT NULL AS has_patch,
56 bug_viewers.access_policy
57 FROM
58 bugsummary_targets(btf_row) AS bug_targets,
59 unnest(tags) AS bug_tags (tag),
60 bugsummary_viewers(btf_row) AS bug_viewers;
61END;
62$$;
63
64-- Modify the existing bugsummary_journal_bugtaskflat to accept an array of
65-- tags, and to return a set of rows to the caller rather than inserting
66-- them into a temporary table. This can now be just SQL rather than
67-- PL/pgSQL.
68DROP FUNCTION bugsummary_journal_bugtaskflat;
69CREATE FUNCTION bugsummary_journal_bugtaskflat(btf_row bugtaskflat, tags text[], _count integer)
70 RETURNS SETOF bugsummaryjournal
71 LANGUAGE sql
72 AS $$
73 SELECT
74 CAST(NULL AS integer) as id,
75 _count, product, productseries, distribution,
76 distroseries, sourcepackagename, viewed_by, tag,
77 status, milestone, importance, has_patch, access_policy
78 FROM bugsummary_locations(btf_row, tags);
79$$;
80
81-- Rewrite the existing bugtaskflat_maintain_bug_summary as a
82-- statement-level trigger.
83CREATE OR REPLACE FUNCTION bugtaskflat_maintain_bug_summary()
84 RETURNS trigger
85 LANGUAGE plpgsql SECURITY DEFINER
86 SET search_path TO 'public'
87 AS $$
88DECLARE
89 summary_queries text[] DEFAULT '{}';
90BEGIN
91 -- Work out the subqueries we need to compute the set of
92 -- BugSummaryJournal rows that should be inserted. (We have to use
93 -- dynamic commands for this, because the transition tables are not
94 -- visible in functions called by this trigger function.)
95 IF TG_OP = 'DELETE' OR TG_OP = 'UPDATE' THEN
96 summary_queries := array_append(summary_queries, $_$
97 SELECT summary.*
98 FROM
99 old_bugtaskflat btf_row,
100 LATERAL bugsummary_journal_bugtaskflat(
101 btf_row, bugsummary_tag_names(btf_row.bug), -1
102 ) AS summary
103 $_$);
104 END IF;
105 IF TG_OP = 'INSERT' OR TG_OP = 'UPDATE' THEN
106 summary_queries := array_append(summary_queries, $_$
107 SELECT summary.*
108 FROM
109 new_bugtaskflat btf_row,
110 LATERAL bugsummary_journal_bugtaskflat(
111 btf_row, bugsummary_tag_names(btf_row.bug), 1
112 ) AS summary
113 $_$);
114 END IF;
115 -- We sum the rows here to minimise the number of inserts into the
116 -- journal, as in the case of UPDATE statement we may have -1s and +1s
117 -- cancelling each other out.
118 EXECUTE ($_$
119 INSERT INTO BugSummaryJournal(
120 count, product, productseries, distribution,
121 distroseries, sourcepackagename, viewed_by, tag,
122 status, milestone, importance, has_patch, access_policy)
123 SELECT
124 SUM(count), product, productseries, distribution,
125 distroseries, sourcepackagename, viewed_by, tag,
126 status, milestone, importance, has_patch, access_policy
127 FROM (
128 $_$ || array_to_string(summary_queries, 'UNION ALL') || $_$
129 ) AS summary
130 GROUP BY
131 product, productseries, distribution,
132 distroseries, sourcepackagename, viewed_by, tag,
133 status, milestone, importance, has_patch, access_policy
134 HAVING SUM(count) != 0;
135 $_$);
136 RETURN NULL;
137END;
138$$;
139
140CREATE TRIGGER bugtaskflat_maintain_bug_summary_insert
141 AFTER INSERT ON bugtaskflat
142 REFERENCING NEW TABLE AS new_bugtaskflat
143 FOR EACH STATEMENT EXECUTE PROCEDURE bugtaskflat_maintain_bug_summary();
144
145CREATE TRIGGER bugtaskflat_maintain_bug_summary_update
146 AFTER UPDATE ON bugtaskflat
147 REFERENCING OLD TABLE AS old_bugtaskflat NEW TABLE AS new_bugtaskflat
148 FOR EACH STATEMENT EXECUTE PROCEDURE bugtaskflat_maintain_bug_summary();
149
150CREATE TRIGGER bugtaskflat_maintain_bug_summary_delete
151 AFTER DELETE ON bugtaskflat
152 REFERENCING OLD TABLE AS old_bugtaskflat
153 FOR EACH STATEMENT EXECUTE PROCEDURE bugtaskflat_maintain_bug_summary();
154
155-- Modify the existing bugsummary_journal_bug to accept an array of tags,
156-- and to return a set of rows to the caller rather than inserting them into
157-- a temporary table. Rephrasing the loop using LATERAL allows this to be
158-- just SQL rather than PL/pgSQL.
159DROP FUNCTION bugsummary_journal_bug;
160CREATE FUNCTION bugsummary_journal_bug(bug_row bug, tags text[], _count integer)
161 RETURNS SETOF bugsummaryjournal
162 LANGUAGE sql
163 AS $$
164 SELECT summary.*
165 FROM
166 bugtaskflat btf_row,
167 LATERAL bugsummary_journal_bugtaskflat(
168 btf_row, tags, _count
169 ) AS summary
170 WHERE bug = bug_row.id;
171$$;
172
173-- Rewrite the existing bugtag_maintain_bug_summary as a statement-level
174-- trigger.
175CREATE OR REPLACE FUNCTION bugtag_maintain_bug_summary()
176 RETURNS trigger
177 LANGUAGE plpgsql SECURITY DEFINER
178 SET search_path TO 'public'
179 AS $$
180DECLARE
181 summary_queries text[] DEFAULT '{}';
182BEGIN
183 -- Work out the subqueries we need to compute the set of
184 -- BugSummaryJournal rows that should be inserted. (We have to use
185 -- dynamic commands for this, because the transition tables are not
186 -- visible in functions called by this trigger function.)
187 IF TG_OP = 'DELETE' OR TG_OP = 'UPDATE' THEN
188 summary_queries := array_append(summary_queries, $_$
189 SELECT summary.*
190 FROM
191 (SELECT bug, array_agg(tag) AS tags
192 FROM old_bugtag
193 GROUP BY bug) AS grouped_bugtags,
194 LATERAL bugsummary_journal_bug(
195 bug_row(grouped_bugtags.bug), grouped_bugtags.tags, -1
196 ) AS summary
197 $_$);
198 END IF;
199 IF TG_OP = 'INSERT' OR TG_OP = 'UPDATE' THEN
200 summary_queries := array_append(summary_queries, $_$
201 SELECT summary.*
202 FROM
203 (SELECT bug, array_agg(tag) AS tags
204 FROM new_bugtag
205 GROUP BY bug) AS grouped_bugtags,
206 LATERAL bugsummary_journal_bug(
207 bug_row(grouped_bugtags.bug), grouped_bugtags.tags, 1
208 ) AS summary
209 $_$);
210 END IF;
211 -- We sum the rows here to minimise the number of inserts into the
212 -- journal, as in the case of UPDATE statement we may have -1s and +1s
213 -- cancelling each other out.
214 EXECUTE ($_$
215 INSERT INTO BugSummaryJournal(
216 count, product, productseries, distribution,
217 distroseries, sourcepackagename, viewed_by, tag,
218 status, milestone, importance, has_patch, access_policy)
219 SELECT
220 SUM(count), product, productseries, distribution,
221 distroseries, sourcepackagename, viewed_by, tag,
222 status, milestone, importance, has_patch, access_policy
223 FROM (
224 $_$ || array_to_string(summary_queries, 'UNION ALL') || $_$
225 ) AS summary
226 GROUP BY
227 product, productseries, distribution,
228 distroseries, sourcepackagename, viewed_by, tag,
229 status, milestone, importance, has_patch, access_policy
230 HAVING SUM(count) != 0;
231 $_$);
232 RETURN NULL;
233END;
234$$;
235
236CREATE TRIGGER bugtag_maintain_bug_summary_insert
237 AFTER INSERT ON bugtag
238 REFERENCING NEW TABLE AS new_bugtag
239 FOR EACH STATEMENT EXECUTE PROCEDURE bugtag_maintain_bug_summary();
240
241CREATE TRIGGER bugtag_maintain_bug_summary_update
242 AFTER UPDATE ON bugtag
243 REFERENCING OLD TABLE AS old_bugtag NEW TABLE AS new_bugtag
244 FOR EACH STATEMENT EXECUTE PROCEDURE bugtag_maintain_bug_summary();
245
246CREATE TRIGGER bugtag_maintain_bug_summary_delete
247 AFTER DELETE ON bugtag
248 REFERENCING OLD TABLE AS old_bugtag
249 FOR EACH STATEMENT EXECUTE PROCEDURE bugtag_maintain_bug_summary();
250
251INSERT INTO LaunchpadDatabaseRevision VALUES (2210, 06, 0);
0252
=== modified file 'database/schema/security.cfg'
--- database/schema/security.cfg 2019-08-09 12:04:04 +0000
+++ database/schema/security.cfg 2019-08-14 14:18:02 +0000
@@ -90,10 +90,11 @@
90public.bug_summary_dec(bugsummary) =90public.bug_summary_dec(bugsummary) =
91public.bug_summary_flush_temp_journal() =91public.bug_summary_flush_temp_journal() =
92public.bug_summary_inc(bugsummary) =92public.bug_summary_inc(bugsummary) =
93public.bugsummary_journal_bug(bug, integer) =93public.bugsummary_journal_bug(bug, text[], integer) =
94public.bugsummary_journal_bugtaskflat(bugtaskflat, integer) =94public.bugsummary_journal_bugtaskflat(bugtaskflat, text[], integer) =
95public.bugsummary_locations(bugtaskflat) =95public.bugsummary_locations(bugtaskflat, text[]) =
96public.bugsummary_tags(bugtaskflat) =96public.bugsummary_tags(bugtaskflat) =
97public.bugsummary_tag_names(integer) =
97public.bugsummary_targets(bugtaskflat) =98public.bugsummary_targets(bugtaskflat) =
98public.bugsummary_viewers(bugtaskflat) =99public.bugsummary_viewers(bugtaskflat) =
99public.ensure_bugsummary_temp_journal() =100public.ensure_bugsummary_temp_journal() =

Subscribers

People subscribed via source and target branches

to status/vote changes: