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

Subscribers

People subscribed via source and target branches

to status/vote changes: