fix some things

This commit is contained in:
Dull Bananas 2023-12-30 17:34:01 +00:00
parent d67bd5f249
commit 0844a7612a

View file

@ -48,91 +48,88 @@ $$;
-- * `old_table` with old rows -- * `old_table` with old rows
-- * `new_table` with new rows -- * `new_table` with new rows
-- * `combined_transition_tables` with both old and new rows, with 2 columns: -- * `combined_transition_tables` with both old and new rows, with 2 columns:
-- 1. `-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. 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, command text) CREATE PROCEDURE r.create_triggers (table_name text, command text)
LANGUAGE plpgsql LANGUAGE plpgsql
AS $a$ AS $a$
DECLARE DECLARE
defs text := $b$ -- `PERFORM` isn't used because it doesn't allow `WITH`
CREATE FUNCTION r.thing_delete_statement () defs text := $b$
RETURNS TRIGGER -- Delete
LANGUAGE plpgsql CREATE FUNCTION r.thing_delete_statement ()
AS $$ RETURNS TRIGGER
BEGIN LANGUAGE plpgsql
PERFORM ( AS $$
WITH DECLARE
combined_transition_tables AS ( foo int;
select_old_table
),
trigger_result AS command
SELECT
1
);
RETURN NULL;
END
$$;
CREATE TRIGGER delete_statement
AFTER DELETE ON thing REFERENCING OLD TABLE AS old_table
FOR EACH STATEMENT
EXECUTE FUNCTION r.thing_delete_statement ();
CREATE FUNCTION r.thing_insert_statement ()
RETURNS TRIGGER
LANGUAGE plpgsql
AS $$
BEGIN
PERFORM (
WITH
combined_transition_tables AS (
select_new_table
),
trigger_result AS command
SELECT
1
);
RETURN NULL;
END
$$;
CREATE TRIGGER insert_statement
AFTER DELETE ON thing REFERENCING NEW TABLE AS new_table
FOR EACH STATEMENT
EXECUTE FUNCTION r.thing_insert_statement ();
CREATE FUNCTION r.thing_update_statement ()
RETURNS TRIGGER
LANGUAGE plpgsql
AS $$
BEGIN
PERFORM (
WITH
combined_transition_tables AS (
select_old_table
UNION ALL
select_new_table
),
trigger_result AS command
SELECT
1
);
RETURN NULL;
END
$$;
CREATE TRIGGER update_statement
AFTER UPDATE ON thing REFERENCING OLD TABLE AS old_table NEW TABLE AS new_table
FOR EACH STATEMENT
EXECUTE FUNCTION r.thing_update_statement ();
$b$;
BEGIN BEGIN
defs := replace(defs, 'select_old_table', $$ WITH combined_transition_tables AS (
SELECT -1 AS count_diff, old_table AS thing FROM old_table select_old_table
$$); ),
defs := replace(defs, 'select_new_table', $$ trigger_result AS command
SELECT 1 AS count_diff, new_table AS thing FROM new_table SELECT
$$); 1 INTO foo;
defs := replace(defs, 'thing', table_name); RETURN NULL;
defs := replace(defs, 'command', format('(%s)', command)); END $$;
EXECUTE defs; CREATE TRIGGER delete_statement
END AFTER DELETE ON thing REFERENCING OLD TABLE AS old_table
FOR EACH STATEMENT
EXECUTE FUNCTION r.thing_delete_statement ( );
-- Insert
CREATE FUNCTION r.thing_insert_statement ( )
RETURNS TRIGGER
LANGUAGE plpgsql
AS $$
DECLARE
foo int;
BEGIN
WITH combined_transition_tables AS (
select_new_table
),
trigger_result AS command
SELECT
1 INTO foo;
RETURN NULL;
END $$;
CREATE TRIGGER insert_statement
AFTER INSERT ON thing REFERENCING NEW TABLE AS new_table
FOR EACH STATEMENT
EXECUTE FUNCTION r.thing_insert_statement ( );
-- Update
CREATE FUNCTION r.thing_update_statement ( )
RETURNS TRIGGER
LANGUAGE plpgsql
AS $$
DECLARE
foo int;
BEGIN
WITH combined_transition_tables AS (
select_old_table
UNION ALL select_new_table
),
trigger_result AS command
SELECT
1 INTO foo;
RETURN NULL;
END $$;
CREATE TRIGGER update_statement
AFTER UPDATE ON thing REFERENCING OLD TABLE AS old_table NEW TABLE AS new_table
FOR EACH STATEMENT
EXECUTE FUNCTION r.thing_update_statement ( );
$b$;
BEGIN
defs := replace(defs, 'select_old_table', $$
SELECT
-1 AS count_diff, old_table::thing AS thing FROM old_table $$);
defs := replace(defs, 'select_new_table', $$
SELECT
1 AS count_diff, new_table::thing AS thing FROM new_table $$);
defs := replace(defs, 'thing', table_name);
defs := replace(defs, 'command', format('(%s)', command));
EXECUTE defs;
END
$a$; $a$;
-- Define functions -- Define functions
@ -150,7 +147,7 @@ CREATE FUNCTION r.creator_id_from_comment_aggregates (agg comment_aggregates)
); );
-- Create triggers for both post and comments -- Create triggers for both post and comments
CREATE PROCEDURE r.post_or_comment (thing_type text) CREATE PROCEDURE r.post_or_comment (table_name text)
LANGUAGE plpgsql LANGUAGE plpgsql
AS $a$ AS $a$
BEGIN BEGIN
@ -180,46 +177,28 @@ BEGIN
FOR EACH STATEMENT FOR EACH STATEMENT
EXECUTE FUNCTION r.resolve_reports_when_thing_removed ( ); EXECUTE FUNCTION r.resolve_reports_when_thing_removed ( );
-- 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', $$ WITH thing_diff AS ( UPDATE
WITH thing_diff AS ( thing_aggregates AS a
UPDATE SET
thing_aggregates AS a score = a.score + diff.upvotes - diff.downvotes, upvotes = a.upvotes + diff.upvotes, downvotes = a.downvotes + diff.downvotes, controversy_rank = controversy_rank ((a.upvotes + diff.upvotes)::numeric, (a.downvotes + diff.downvotes)::numeric)
SET FROM (
score = a.score + diff.upvotes - diff.downvotes, SELECT
upvotes = a.upvotes + diff.upvotes, (thing_like).thing_id, sum(count_diff) FILTER (WHERE (thing_like).score = 1) AS upvotes, sum(count_diff) FILTER (WHERE (thing_like).score != 1) AS downvotes FROM combined_transition_tables GROUP BY (thing_like).thing_id) AS diff
downvotes = a.downvotes + diff.downvotes, WHERE
controversy_rank = controversy_rank ((a.upvotes + diff.upvotes)::numeric, (a.downvotes + diff.downvotes)::numeric) a.thing_id = diff.thing_id
FROM ( RETURNING
SELECT creator_id_from_thing_aggregates (a.*) AS creator_id, diff.upvotes - diff.downvotes AS score)
(thing_like).thing_id, UPDATE
sum(count_diff) FILTER (WHERE (thing_like).score = 1) AS upvotes, person_aggregates AS a
sum(count_diff) FILTER (WHERE (thing_like).score != 1) AS downvotes SET
FROM thing_score = a.thing_score + diff.score FROM (
combined_transition_tables
AS (count_diff bigint,
thing_like thing_like)
GROUP BY
(thing_like).thing_id) AS diff
WHERE
a.thing_id = diff.thing_id
RETURNING
creator_id_from_thing_aggregates (a.*) AS creator_id,
diff.upvotes - diff.downvotes AS score)
UPDATE
person_aggregates AS a
SET
thing_score = a.thing_score + diff.score
FROM (
SELECT SELECT
creator_id, creator_id, sum(score) AS score FROM target_diff GROUP BY creator_id) AS diff
sum(score) AS score WHERE
FROM a.person_id = diff.creator_id $$);
target_diff $b$,
GROUP BY 'thing',
creator_id) AS diff table_name);
WHERE
a.person_id = diff.creator_id
$$);
END END
$a$; $a$;
@ -228,24 +207,16 @@ 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', $$ WITH comment_group AS (
WITH comment_group AS (
SELECT SELECT
(comment).post_id, (comment).post_id,
(comment).creator_id, (comment).creator_id,
(comment).local, (comment).local,
sum(count_diff) AS comments sum(count_diff) AS comments FROM combined_transition_tables
FROM WHERE
combined_transition_tables NOT ((comment).deleted
AS (count_diff bigint, OR (comment).removed)
comment comment) GROUP BY GROUPING SETS ((comment).post_id, (comment).creator_id, (comment).local)),
WHERE
NOT ((comment).deleted OR (comment).removed)
GROUP BY
GROUPING SETS ((comment).post_id,
(comment).creator_id,
(comment).local)
),
unused_person_aggregates_update_result AS ( unused_person_aggregates_update_result AS (
UPDATE UPDATE
person_aggregates AS a person_aggregates AS a
@ -254,149 +225,114 @@ unused_person_aggregates_update_result AS (
FROM FROM
comment_group comment_group
WHERE WHERE
a.person_id = comment_group.creator_id a.person_id = comment_group.creator_id),
), unused_site_aggregates_update_result AS (
unused_site_aggregates_update_result AS ( UPDATE
UPDATE site_aggregates AS a
site_aggregates AS a SET
SET comments = a.comments + comment_group.comments
comments = a.comments + comment_group.comments
FROM
comment_group
WHERE
comment_group.local
),
post_diff AS (
UPDATE
post_aggregates AS a
SET
comments = a.comments + comment_group.comments,
newest_comment_time = GREATEST (a.newest_comment_time, (
SELECT
max(published)
FROM new_table AS new_comment
WHERE
a.post_id = new_comment.post_id LIMIT 1)),
newest_comment_time_necro = GREATEST (a.newest_comment_time_necro, (
SELECT
max(published)
FROM new_table 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)
LIMIT 1))
FROM
comment_group,
LATERAL (
SELECT
*
FROM
post
WHERE
a.post_id = post.id
LIMIT 1) AS post
WHERE
a.post_id = comment_group.post_id
RETURNING
a.community_id,
diff.comments,
NOT (post.deleted
OR post.removed) AS include_in_community_aggregates)
UPDATE
community_aggregates AS a
SET
comments = a.comments + diff.comments
FROM (
SELECT
community_id,
sum(comments)
FROM
post_diff
WHERE
post_diff.include_in_community_aggregates
GROUP BY
community_id) AS diff
WHERE
a.community_id = diff.community_id
$$);
CALL r.create_triggers('post', $$
WITH post_group AS (
SELECT
(post).community_id,
(post).creator_id,
(post).local,
sum(count_diff) AS posts
FROM FROM
combined_post_transition_tables comment_group
AS (count_diff bigint,
post post)
WHERE WHERE
NOT ((post).deleted OR (post).removed) comment_group.local),
GROUP BY post_diff AS (
GROUPING SETS ((post).community_id, UPDATE
(post).creator_id, post_aggregates AS a
(post).local) SET
), comments = a.comments + comment_group.comments,
unused_person_aggregates_update_result AS ( newest_comment_time = GREATEST (a.newest_comment_time, (
UPDATE SELECT
max(published)
FROM new_table AS new_comment
WHERE
a.post_id = new_comment.post_id LIMIT 1)),
newest_comment_time_necro = GREATEST (a.newest_comment_time_necro, (
SELECT
max(published)
FROM new_table 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)
LIMIT 1))
FROM
comment_group,
LATERAL (
SELECT
*
FROM
post
WHERE
a.post_id = post.id
LIMIT 1) AS post
WHERE
a.post_id = comment_group.post_id
RETURNING
a.community_id,
diff.comments,
NOT (post.deleted
OR post.removed) AS include_in_community_aggregates)
UPDATE
community_aggregates AS a
SET
comments = a.comments + diff.comments
FROM (
SELECT
community_id, sum(comments)
FROM
post_diff
WHERE
post_diff.include_in_community_aggregates
GROUP BY
community_id) AS diff
WHERE
a.community_id = diff.community_id $$);
CALL r.create_triggers ('post', $$ WITH post_group AS (
SELECT
(post).community_id, (post).creator_id, (post).local, sum(count_diff) AS posts FROM combined_transition_tables
WHERE
NOT ((post).deleted
OR (post).removed)
GROUP BY GROUPING SETS ((post).community_id, (post).creator_id, (post).local)
), unused_person_aggregates_update_result AS ( UPDATE
person_aggregates AS a person_aggregates AS a
SET SET
post_count = a.post_count + post_group.posts post_count = a.post_count + post_group.posts FROM post_group
FROM WHERE
post_group a.person_id = post_group.creator_id
WHERE ), unused_site_aggregates_update_result AS ( UPDATE
a.person_id = post_group.creator_id
),
unused_site_aggregates_update_result AS (
UPDATE
site_aggregates AS a site_aggregates AS a
SET SET
posts = a.posts + post_group.posts posts = a.posts + post_group.posts FROM post_group
FROM WHERE
post_group post_group.local)
WHERE UPDATE
post_group.local) community_aggregates AS a
UPDATE SET
community_aggregates AS a posts = a.posts + post_group.posts FROM post_group
SET WHERE
posts = a.posts + post_group.posts a.community_id = post_group.community_id $$);
FROM
post_group
WHERE
a.community_id = post_group.community_id
$$);
CALL r.create_triggers('community', $$ CALL r.create_triggers ('community', $$ UPDATE
UPDATE
site_aggregates AS a site_aggregates AS a
SET SET
communities = a.communities + diff.communities communities = a.communities + diff.communities FROM (
FROM ( SELECT
SELECT sum(count_diff) AS communities FROM combined_transition_tables
sum(count_diff) AS communities WHERE (community).local
FROM AND NOT ((community).deleted
combined_transition_tables OR (community).removed)) AS diff $$);
AS (count_diff bigint, community community)
WHERE (community).local AND NOT ((community).deleted OR (community).removed)) AS diff
$$);
CALL r.create_triggers('person', $$ CALL r.create_triggers ('person', $$ UPDATE
UPDATE
site_aggregates AS a site_aggregates AS a
SET SET
users = a.users + diff.users users = a.users + diff.users FROM (
FROM ( SELECT
SELECT sum(count_diff) AS users FROM combined_transition_tables
sum(count_diff) AS users WHERE (person).local) AS diff $$);
FROM
combined_transition_tables
AS (count_diff bigint, person person)
WHERE (person).local) AS diff
$$);
-- For community_aggregates.comments, don't include comments of deleted or removed posts -- For community_aggregates.comments, don't include comments of deleted or removed posts
CREATE FUNCTION r.update_comment_count_from_post () CREATE FUNCTION r.update_comment_count_from_post ()
@ -446,31 +382,21 @@ CREATE TRIGGER comment_count
EXECUTE FUNCTION r.update_comment_count_from_post (); EXECUTE FUNCTION r.update_comment_count_from_post ();
-- Count subscribers for local communities -- Count subscribers for local communities
CALL r.create_triggers ('community_follower', $$ CALL r.create_triggers ('community_follower', $$ UPDATE
UPDATE
community_aggregates AS a community_aggregates AS a
SET SET
subscriber = a.subscribers + diff.subscribers subscriber = a.subscribers + diff.subscribers FROM (
FROM ( SELECT
SELECT (community_follower).community_id, sum(count_diff) AS subscribers FROM combined_transition_tables
(community_follower).community_id, WHERE (
sum(count_diff) AS subscribers SELECT
FROM local
combine_transition_tables FROM community
AS (count_diff bigint, community_follower community_follower) WHERE
WHERE ( community.id = (community_follower).community_id LIMIT 1)
SELECT GROUP BY (community_follower).community_id) AS diff
local WHERE
FROM a.community_id = diff.community_id $$);
community
WHERE
community.id = (community_follower).community_id
LIMIT 1)
GROUP BY
(community_follower).community_id) AS diff
WHERE
a.community_id = diff.community_id
$$);
-- These triggers create and update rows in each aggregates table to match its associated table's rows. -- These triggers create and update rows in each aggregates table to match its associated table's rows.
-- Deleting rows and updating IDs are already handled by `CASCADE` in foreign key constraints. -- Deleting rows and updating IDs are already handled by `CASCADE` in foreign key constraints.
@ -501,7 +427,7 @@ CREATE FUNCTION r.community_aggregates_from_community ()
BEGIN BEGIN
INSERT INTO community_aggregates (community_id, published) INSERT INTO community_aggregates (community_id, published)
SELECT SELECT
community_id, id,
published published
FROM FROM
new_community; new_community;