separate triggers

This commit is contained in:
Dull Bananas 2024-05-04 15:32:49 +00:00
parent b152be7951
commit 95600da4af
3 changed files with 117 additions and 92 deletions

View file

@ -27,7 +27,7 @@ AS $a$
BEGIN BEGIN
EXECUTE replace($b$ EXECUTE replace($b$
-- When a thing gets a vote, update its aggregates and its creator's aggregates -- 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 BEGIN
WITH thing_diff AS ( UPDATE WITH thing_diff AS ( UPDATE
thing_aggregates AS a thing_aggregates AS a
@ -62,7 +62,7 @@ CALL r.post_or_comment ('post');
CALL r.post_or_comment ('comment'); CALL r.post_or_comment ('comment');
-- Create triggers that update counts in parent aggregates -- Create triggers that update counts in parent aggregates
CALL r.create_triggers ('comment', $$ CALL r.create_triggers ('comment', 'person_aggregates', $$
BEGIN BEGIN
UPDATE UPDATE
person_aggregates AS a person_aggregates AS a
@ -78,66 +78,74 @@ BEGIN
WHERE WHERE
a.person_id = diff.creator_id; a.person_id = diff.creator_id;
UPDATE RETURN NULL;
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;
WITH post_diff AS ( END;
$$);
CALL r.create_triggers ('comment', 'site_aggregates', $$
BEGIN
UPDATE UPDATE
post_aggregates AS a site_aggregates AS a
SET SET
comments = a.comments + diff.comments, 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 ( FROM (
SELECT SELECT
(comment).post_id,
coalesce(sum(count_diff), 0) AS comments coalesce(sum(count_diff), 0) AS comments
FROM FROM select_old_and_new_rows AS old_and_new_rows
select_old_and_new_rows AS old_and_new_rows WHERE
WHERE r.is_counted (comment)
r.is_counted (comment) AND (comment).local) AS diff;
GROUP BY
(comment).post_id) AS diff RETURN NULL;
LEFT JOIN post ON post.id = diff.post_id
WHERE END;
a.post_id = diff.post_id
RETURNING $$);
a.community_id,
diff.comments, CALL r.create_triggers ('comment', 'post_aggregates_and_community_aggregates', $$
r.is_counted (post.*) AS include_in_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 UPDATE
community_aggregates AS a community_aggregates AS a
SET SET
comments = a.comments + diff.comments comments = a.comments + diff.comments
FROM ( FROM (
SELECT SELECT
community_id, community_id, sum(comments) AS comments
sum(comments) AS comments
FROM FROM
post_diff post_diff
WHERE WHERE
@ -153,7 +161,7 @@ END;
$$); $$);
CALL r.create_triggers ('post', $$ CALL r.create_triggers ('post', 'person_aggregates', $$
BEGIN BEGIN
UPDATE UPDATE
person_aggregates AS a person_aggregates AS a
@ -169,33 +177,45 @@ BEGIN
WHERE WHERE
a.person_id = diff.creator_id; a.person_id = diff.creator_id;
UPDATE RETURN NULL;
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;
UPDATE END;
community_aggregates AS a
SET $$);
posts = a.posts + diff.posts
FROM ( CALL r.create_triggers ('post', 'site_aggregates', $$
SELECT BEGIN
(post).community_id, UPDATE
coalesce(sum(count_diff), 0) AS posts site_aggregates AS a
FROM SET
select_old_and_new_rows AS old_and_new_rows posts = a.posts + diff.posts
WHERE FROM (
r.is_counted (post) SELECT
GROUP BY coalesce(sum(count_diff), 0) AS posts
(post).community_id) AS diff 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 WHERE
a.community_id = diff.community_id; a.community_id = diff.community_id;
@ -205,7 +225,7 @@ END;
$$); $$);
CALL r.create_triggers ('community', $$ CALL r.create_triggers ('community', 'site_aggregates', $$
BEGIN BEGIN
UPDATE UPDATE
site_aggregates AS a site_aggregates AS a
@ -225,7 +245,7 @@ END;
$$); $$);
CALL r.create_triggers ('person', $$ CALL r.create_triggers ('person', 'site_aggregates', $$
BEGIN BEGIN
UPDATE UPDATE
site_aggregates AS a site_aggregates AS a
@ -283,7 +303,7 @@ CREATE TRIGGER comment_count
-- Count subscribers for communities. -- Count subscribers for communities.
-- subscribers should be updated only when a local community is followed by a local or remote person. -- 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. -- 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 BEGIN
UPDATE UPDATE
community_aggregates AS a community_aggregates AS a

View file

@ -64,46 +64,46 @@ $$;
-- not allowed for a `DELETE` trigger) -- not allowed for a `DELETE` trigger)
-- * Transition tables are only provided to the trigger function, not to functions that it calls. -- * 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 -- The trigger function body is given as the 2nd argument and can contain these names, which are
-- and can contain these names, which are replaced with a `SELECT` statement in parenthesis if needed: -- replaced with a `SELECT` statement in parenthesis if needed:
-- * `select_old_rows` -- * `select_old_rows`
-- * `select_new_rows` -- * `select_new_rows`
-- * `select_old_and_new_rows` with 2 columns: -- * `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 -- 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 -- to add to a count
-- 2. (same name as the trigger's table): the old or new row as a composite value -- 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 LANGUAGE plpgsql
AS $a$ AS $a$
DECLARE DECLARE
defs text := $$ defs text := $$
-- Delete -- Delete
CREATE FUNCTION r.thing_delete_statement () CREATE FUNCTION r.thing_trigger_name_for_delete_statement ()
RETURNS TRIGGER RETURNS TRIGGER
LANGUAGE plpgsql LANGUAGE plpgsql
AS function_body_delete; 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 AFTER DELETE ON thing REFERENCING OLD TABLE AS select_old_rows
FOR EACH STATEMENT FOR EACH STATEMENT
EXECUTE FUNCTION r.thing_delete_statement ( ); EXECUTE FUNCTION r.thing_trigger_name_for_delete_statement ( );
-- Insert -- Insert
CREATE FUNCTION r.thing_insert_statement ( ) CREATE FUNCTION r.thing_trigger_name_for_insert_statement ( )
RETURNS TRIGGER RETURNS TRIGGER
LANGUAGE plpgsql LANGUAGE plpgsql
AS function_body_insert; 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 AFTER INSERT ON thing REFERENCING NEW TABLE AS select_new_rows
FOR EACH STATEMENT FOR EACH STATEMENT
EXECUTE FUNCTION r.thing_insert_statement ( ); EXECUTE FUNCTION r.thing_trigger_name_for_insert_statement ( );
-- Update -- Update
CREATE FUNCTION r.thing_update_statement ( ) CREATE FUNCTION r.thing_trigger_name_for_update_statement ( )
RETURNS TRIGGER RETURNS TRIGGER
LANGUAGE plpgsql LANGUAGE plpgsql
AS function_body_update; 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 AFTER UPDATE ON thing REFERENCING OLD TABLE AS select_old_rows NEW TABLE AS select_new_rows
FOR EACH STATEMENT 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_old_and_new_rows text := $$ (
SELECT SELECT
@ -135,6 +135,7 @@ DECLARE
FALSE) $$; FALSE) $$;
BEGIN BEGIN
function_body := replace(function_body, 'select_old_and_new_rows', select_old_and_new_rows); 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 -- `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_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))); defs := replace(defs, 'function_body_insert', quote_literal(replace(function_body, 'select_old_rows', empty_select_old_rows)));

View file

@ -0,0 +1,4 @@
-- This migration exists to trigger re-execution of replaceable_schema
SELECT
1;