From 95600da4afb49e1dc203c2d61da4c57858e107db Mon Sep 17 00:00:00 2001 From: Dull Bananas Date: Sat, 4 May 2024 15:32:49 +0000 Subject: [PATCH] separate triggers --- .../db_schema/replaceable_schema/triggers.sql | 180 ++++++++++-------- crates/db_schema/replaceable_schema/utils.sql | 25 +-- .../up.sql | 4 + 3 files changed, 117 insertions(+), 92 deletions(-) create mode 100644 migrations/2024-05-04-140749_separate_triggers/up.sql diff --git a/crates/db_schema/replaceable_schema/triggers.sql b/crates/db_schema/replaceable_schema/triggers.sql index d869a5e1e..141dfe414 100644 --- a/crates/db_schema/replaceable_schema/triggers.sql +++ b/crates/db_schema/replaceable_schema/triggers.sql @@ -27,7 +27,7 @@ AS $a$ BEGIN EXECUTE replace($b$ -- When a thing gets a vote, update its aggregates and its creator's aggregates - CALL r.create_triggers ('thing_like', $$ + CALL r.create_triggers ('thing_like', 'thing_aggregates_and_person_aggregates', $$ BEGIN WITH thing_diff AS ( UPDATE thing_aggregates AS a @@ -62,7 +62,7 @@ CALL r.post_or_comment ('post'); CALL r.post_or_comment ('comment'); -- Create triggers that update counts in parent aggregates -CALL r.create_triggers ('comment', $$ +CALL r.create_triggers ('comment', 'person_aggregates', $$ BEGIN UPDATE person_aggregates AS a @@ -78,66 +78,74 @@ BEGIN WHERE a.person_id = diff.creator_id; -UPDATE - site_aggregates AS a -SET - comments = a.comments + diff.comments -FROM ( - SELECT - coalesce(sum(count_diff), 0) AS comments - FROM - select_old_and_new_rows AS old_and_new_rows - WHERE - r.is_counted (comment) - AND (comment).local) AS diff; +RETURN NULL; -WITH post_diff AS ( +END; + +$$); + +CALL r.create_triggers ('comment', 'site_aggregates', $$ +BEGIN UPDATE - post_aggregates AS a + site_aggregates AS a SET - comments = a.comments + diff.comments, - newest_comment_time = GREATEST (a.newest_comment_time, ( - SELECT - published - FROM select_new_rows AS new_comment - WHERE - a.post_id = new_comment.post_id ORDER BY published DESC LIMIT 1)), - newest_comment_time_necro = GREATEST (a.newest_comment_time_necro, ( - SELECT - published - FROM select_new_rows AS new_comment - WHERE - a.post_id = new_comment.post_id - -- Ignore comments from the post's creator - AND a.creator_id != new_comment.creator_id - -- Ignore comments on old posts - AND a.published > (new_comment.published - '2 days'::interval) - ORDER BY published DESC LIMIT 1)) + comments = a.comments + diff.comments FROM ( SELECT - (comment).post_id, coalesce(sum(count_diff), 0) AS comments - FROM - select_old_and_new_rows AS old_and_new_rows - WHERE - r.is_counted (comment) - GROUP BY - (comment).post_id) AS diff - LEFT JOIN post ON post.id = diff.post_id - WHERE - a.post_id = diff.post_id - RETURNING - a.community_id, - diff.comments, - r.is_counted (post.*) AS include_in_community_aggregates) + FROM select_old_and_new_rows AS old_and_new_rows + WHERE + r.is_counted (comment) + AND (comment).local) AS diff; + +RETURN NULL; + +END; + +$$); + +CALL r.create_triggers ('comment', 'post_aggregates_and_community_aggregates', $$ +BEGIN + WITH post_diff AS ( + UPDATE + post_aggregates AS a + SET + comments = a.comments + diff.comments, + newest_comment_time = GREATEST (a.newest_comment_time, ( + SELECT + published + FROM select_new_rows AS new_comment + WHERE + a.post_id = new_comment.post_id ORDER BY published DESC LIMIT 1)), newest_comment_time_necro = GREATEST (a.newest_comment_time_necro, ( + SELECT + published + FROM select_new_rows AS new_comment + WHERE + a.post_id = new_comment.post_id + -- Ignore comments from the post's creator + AND a.creator_id != new_comment.creator_id + -- Ignore comments on old posts + AND a.published > (new_comment.published - '2 days'::interval) + ORDER BY published DESC LIMIT 1)) + FROM ( + SELECT + (comment).post_id, coalesce(sum(count_diff), 0) AS comments + FROM select_old_and_new_rows AS old_and_new_rows + WHERE + r.is_counted (comment) + GROUP BY (comment).post_id) AS diff + LEFT JOIN post ON post.id = diff.post_id + WHERE + a.post_id = diff.post_id + RETURNING + a.community_id, diff.comments, r.is_counted (post.*) AS include_in_community_aggregates) UPDATE community_aggregates AS a SET comments = a.comments + diff.comments FROM ( SELECT - community_id, - sum(comments) AS comments + community_id, sum(comments) AS comments FROM post_diff WHERE @@ -153,7 +161,7 @@ END; $$); -CALL r.create_triggers ('post', $$ +CALL r.create_triggers ('post', 'person_aggregates', $$ BEGIN UPDATE person_aggregates AS a @@ -169,33 +177,45 @@ BEGIN WHERE a.person_id = diff.creator_id; -UPDATE - site_aggregates AS a -SET - posts = a.posts + diff.posts -FROM ( - SELECT - coalesce(sum(count_diff), 0) AS posts - FROM - select_old_and_new_rows AS old_and_new_rows - WHERE - r.is_counted (post) - AND (post).local) AS diff; +RETURN NULL; -UPDATE - community_aggregates AS a -SET - posts = a.posts + diff.posts -FROM ( - SELECT - (post).community_id, - coalesce(sum(count_diff), 0) AS posts - FROM - select_old_and_new_rows AS old_and_new_rows - WHERE - r.is_counted (post) - GROUP BY - (post).community_id) AS diff +END; + +$$); + +CALL r.create_triggers ('post', 'site_aggregates', $$ +BEGIN + UPDATE + site_aggregates AS a + SET + posts = a.posts + diff.posts + FROM ( + SELECT + coalesce(sum(count_diff), 0) AS posts + FROM select_old_and_new_rows AS old_and_new_rows + WHERE + r.is_counted (post) + AND (post).local) AS diff; + +RETURN NULL; + +END; + +$$); + +CALL r.create_triggers ('post', 'community_aggregates', $$ +BEGIN + UPDATE + community_aggregates AS a + SET + posts = a.posts + diff.posts + FROM ( + SELECT + (post).community_id, coalesce(sum(count_diff), 0) AS posts + FROM select_old_and_new_rows AS old_and_new_rows + WHERE + r.is_counted (post) + GROUP BY (post).community_id) AS diff WHERE a.community_id = diff.community_id; @@ -205,7 +225,7 @@ END; $$); -CALL r.create_triggers ('community', $$ +CALL r.create_triggers ('community', 'site_aggregates', $$ BEGIN UPDATE site_aggregates AS a @@ -225,7 +245,7 @@ END; $$); -CALL r.create_triggers ('person', $$ +CALL r.create_triggers ('person', 'site_aggregates', $$ BEGIN UPDATE site_aggregates AS a @@ -283,7 +303,7 @@ CREATE TRIGGER comment_count -- Count subscribers for communities. -- subscribers should be updated only when a local community is followed by a local or remote person. -- subscribers_local should be updated only when a local person follows a local or remote community. -CALL r.create_triggers ('community_follower', $$ +CALL r.create_triggers ('community_follower', 'community_aggregates', $$ BEGIN UPDATE community_aggregates AS a diff --git a/crates/db_schema/replaceable_schema/utils.sql b/crates/db_schema/replaceable_schema/utils.sql index f236c5387..9d90adebd 100644 --- a/crates/db_schema/replaceable_schema/utils.sql +++ b/crates/db_schema/replaceable_schema/utils.sql @@ -64,46 +64,46 @@ $$; -- not allowed for a `DELETE` trigger) -- * Transition tables are only provided to the trigger function, not to functions that it calls. -- --- This function can only be called once per table. The trigger function body given as the 2nd argument --- and can contain these names, which are replaced with a `SELECT` statement in parenthesis if needed: +-- The trigger function body is given as the 2nd argument and can contain these names, which are +-- replaced with a `SELECT` statement in parenthesis if needed: -- * `select_old_rows` -- * `select_new_rows` -- * `select_old_and_new_rows` with 2 columns: -- 1. `count_diff`: `-1` for old rows and `1` for new rows, which can be used with `sum` to get the number -- to add to a count -- 2. (same name as the trigger's table): the old or new row as a composite value -CREATE PROCEDURE r.create_triggers (table_name text, function_body text) +CREATE PROCEDURE r.create_triggers (table_name text, trigger_name text, function_body text) LANGUAGE plpgsql AS $a$ DECLARE defs text := $$ -- Delete - CREATE FUNCTION r.thing_delete_statement () + CREATE FUNCTION r.thing_trigger_name_for_delete_statement () RETURNS TRIGGER LANGUAGE plpgsql AS function_body_delete; - CREATE TRIGGER delete_statement + CREATE TRIGGER trigger_name_for_delete_statement AFTER DELETE ON thing REFERENCING OLD TABLE AS select_old_rows FOR EACH STATEMENT - EXECUTE FUNCTION r.thing_delete_statement ( ); + EXECUTE FUNCTION r.thing_trigger_name_for_delete_statement ( ); -- Insert - CREATE FUNCTION r.thing_insert_statement ( ) + CREATE FUNCTION r.thing_trigger_name_for_insert_statement ( ) RETURNS TRIGGER LANGUAGE plpgsql AS function_body_insert; - CREATE TRIGGER insert_statement + CREATE TRIGGER trigger_name_for_insert_statement AFTER INSERT ON thing REFERENCING NEW TABLE AS select_new_rows FOR EACH STATEMENT - EXECUTE FUNCTION r.thing_insert_statement ( ); + EXECUTE FUNCTION r.thing_trigger_name_for_insert_statement ( ); -- Update - CREATE FUNCTION r.thing_update_statement ( ) + CREATE FUNCTION r.thing_trigger_name_for_update_statement ( ) RETURNS TRIGGER LANGUAGE plpgsql AS function_body_update; - CREATE TRIGGER update_statement + CREATE TRIGGER trigger_name_for_update_statement AFTER UPDATE ON thing REFERENCING OLD TABLE AS select_old_rows NEW TABLE AS select_new_rows FOR EACH STATEMENT - EXECUTE FUNCTION r.thing_update_statement ( ); + EXECUTE FUNCTION r.thing_trigger_name_for_update_statement ( ); $$; select_old_and_new_rows text := $$ ( SELECT @@ -135,6 +135,7 @@ DECLARE FALSE) $$; BEGIN function_body := replace(function_body, 'select_old_and_new_rows', select_old_and_new_rows); + defs := replace(defs, 'trigger_name', trigger_name); -- `select_old_rows` and `select_new_rows` are made available as empty tables if they don't already exist defs := replace(defs, 'function_body_delete', quote_literal(replace(function_body, 'select_new_rows', empty_select_new_rows))); defs := replace(defs, 'function_body_insert', quote_literal(replace(function_body, 'select_old_rows', empty_select_old_rows))); diff --git a/migrations/2024-05-04-140749_separate_triggers/up.sql b/migrations/2024-05-04-140749_separate_triggers/up.sql new file mode 100644 index 000000000..2e9d05052 --- /dev/null +++ b/migrations/2024-05-04-140749_separate_triggers/up.sql @@ -0,0 +1,4 @@ +-- This migration exists to trigger re-execution of replaceable_schema +SELECT + 1; +