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,75 +48,72 @@ $$;
-- * `old_table` with old rows
-- * `new_table` with new rows
-- * `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
-- 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)
LANGUAGE plpgsql
AS $a$
DECLARE
-- `PERFORM` isn't used because it doesn't allow `WITH`
defs text := $b$
-- Delete
CREATE FUNCTION r.thing_delete_statement ()
RETURNS TRIGGER
LANGUAGE plpgsql
AS $$
DECLARE
foo int;
BEGIN
PERFORM (
WITH
combined_transition_tables AS (
WITH combined_transition_tables AS (
select_old_table
),
trigger_result AS command
SELECT
1
);
1 INTO foo;
RETURN NULL;
END
$$;
END $$;
CREATE TRIGGER delete_statement
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
PERFORM (
WITH
combined_transition_tables AS (
WITH combined_transition_tables AS (
select_new_table
),
trigger_result AS command
SELECT
1
);
1 INTO foo;
RETURN NULL;
END
$$;
END $$;
CREATE TRIGGER insert_statement
AFTER DELETE ON thing REFERENCING NEW TABLE AS new_table
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
PERFORM (
WITH
combined_transition_tables AS (
WITH combined_transition_tables AS (
select_old_table
UNION ALL
select_new_table
UNION ALL select_new_table
),
trigger_result AS command
SELECT
1
);
1 INTO foo;
RETURN NULL;
END
$$;
END $$;
CREATE TRIGGER update_statement
AFTER UPDATE ON thing REFERENCING OLD TABLE AS old_table NEW TABLE AS new_table
FOR EACH STATEMENT
@ -124,11 +121,11 @@ DECLARE
$b$;
BEGIN
defs := replace(defs, 'select_old_table', $$
SELECT -1 AS count_diff, old_table AS thing FROM 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 AS thing FROM 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;
@ -150,7 +147,7 @@ CREATE FUNCTION r.creator_id_from_comment_aggregates (agg comment_aggregates)
);
-- 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
AS $a$
BEGIN
@ -180,46 +177,28 @@ BEGIN
FOR EACH STATEMENT
EXECUTE FUNCTION r.resolve_reports_when_thing_removed ( );
-- When a thing gets a vote, update its aggregates and its creator's aggregates
CALL r.create_triggers ('thing_like', $$
WITH thing_diff AS (
UPDATE
CALL r.create_triggers ('thing_like', $$ WITH thing_diff AS ( UPDATE
thing_aggregates AS a
SET
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)
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)
FROM (
SELECT
(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
AS (count_diff bigint,
thing_like thing_like)
GROUP BY
(thing_like).thing_id) AS diff
(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
WHERE
a.thing_id = diff.thing_id
RETURNING
creator_id_from_thing_aggregates (a.*) AS creator_id,
diff.upvotes - diff.downvotes AS score)
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 (
thing_score = a.thing_score + diff.score FROM (
SELECT
creator_id,
sum(score) AS score
FROM
target_diff
GROUP BY
creator_id) AS diff
creator_id, sum(score) AS score FROM target_diff GROUP BY creator_id) AS diff
WHERE
a.person_id = diff.creator_id
$$);
a.person_id = diff.creator_id $$);
$b$,
'thing',
table_name);
END
$a$;
@ -228,24 +207,16 @@ 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', $$
WITH comment_group AS (
CALL r.create_triggers ('comment', $$ WITH comment_group AS (
SELECT
(comment).post_id,
(comment).creator_id,
(comment).local,
sum(count_diff) AS comments
FROM
combined_transition_tables
AS (count_diff bigint,
comment comment)
sum(count_diff) AS comments FROM combined_transition_tables
WHERE
NOT ((comment).deleted OR (comment).removed)
GROUP BY
GROUPING SETS ((comment).post_id,
(comment).creator_id,
(comment).local)
),
NOT ((comment).deleted
OR (comment).removed)
GROUP BY GROUPING SETS ((comment).post_id, (comment).creator_id, (comment).local)),
unused_person_aggregates_update_result AS (
UPDATE
person_aggregates AS a
@ -254,8 +225,7 @@ unused_person_aggregates_update_result AS (
FROM
comment_group
WHERE
a.person_id = comment_group.creator_id
),
a.person_id = comment_group.creator_id),
unused_site_aggregates_update_result AS (
UPDATE
site_aggregates AS a
@ -264,8 +234,7 @@ unused_site_aggregates_update_result AS (
FROM
comment_group
WHERE
comment_group.local
),
comment_group.local),
post_diff AS (
UPDATE
post_aggregates AS a
@ -311,8 +280,7 @@ SET
comments = a.comments + diff.comments
FROM (
SELECT
community_id,
sum(comments)
community_id, sum(comments)
FROM
post_diff
WHERE
@ -320,83 +288,51 @@ FROM (
GROUP BY
community_id) AS diff
WHERE
a.community_id = diff.community_id
$$);
a.community_id = diff.community_id $$);
CALL r.create_triggers('post', $$
WITH post_group AS (
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_post_transition_tables
AS (count_diff bigint,
post post)
(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
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
SET
post_count = a.post_count + post_group.posts
FROM
post_group
post_count = a.post_count + post_group.posts FROM post_group
WHERE
a.person_id = post_group.creator_id
),
unused_site_aggregates_update_result AS (
UPDATE
), unused_site_aggregates_update_result AS ( UPDATE
site_aggregates AS a
SET
posts = a.posts + post_group.posts
FROM
post_group
posts = a.posts + post_group.posts FROM post_group
WHERE
post_group.local)
UPDATE
community_aggregates AS a
SET
posts = a.posts + post_group.posts
FROM
post_group
posts = a.posts + post_group.posts FROM post_group
WHERE
a.community_id = post_group.community_id
$$);
a.community_id = post_group.community_id $$);
CALL r.create_triggers('community', $$
UPDATE
CALL r.create_triggers ('community', $$ UPDATE
site_aggregates AS a
SET
communities = a.communities + diff.communities
FROM (
communities = a.communities + diff.communities FROM (
SELECT
sum(count_diff) AS communities
FROM
combined_transition_tables
AS (count_diff bigint, community community)
WHERE (community).local AND NOT ((community).deleted OR (community).removed)) AS diff
$$);
sum(count_diff) AS communities FROM combined_transition_tables
WHERE (community).local
AND NOT ((community).deleted
OR (community).removed)) AS diff $$);
CALL r.create_triggers('person', $$
UPDATE
CALL r.create_triggers ('person', $$ UPDATE
site_aggregates AS a
SET
users = a.users + diff.users
FROM (
users = a.users + diff.users FROM (
SELECT
sum(count_diff) AS users
FROM
combined_transition_tables
AS (count_diff bigint, person person)
WHERE (person).local) AS diff
$$);
sum(count_diff) AS users FROM combined_transition_tables
WHERE (person).local) AS diff $$);
-- For community_aggregates.comments, don't include comments of deleted or removed posts
CREATE FUNCTION r.update_comment_count_from_post ()
@ -446,31 +382,21 @@ CREATE TRIGGER comment_count
EXECUTE FUNCTION r.update_comment_count_from_post ();
-- Count subscribers for local communities
CALL r.create_triggers ('community_follower', $$
UPDATE
CALL r.create_triggers ('community_follower', $$ UPDATE
community_aggregates AS a
SET
subscriber = a.subscribers + diff.subscribers
FROM (
subscriber = a.subscribers + diff.subscribers FROM (
SELECT
(community_follower).community_id,
sum(count_diff) AS subscribers
FROM
combine_transition_tables
AS (count_diff bigint, community_follower community_follower)
(community_follower).community_id, sum(count_diff) AS subscribers FROM combined_transition_tables
WHERE (
SELECT
local
FROM
community
FROM community
WHERE
community.id = (community_follower).community_id
LIMIT 1)
GROUP BY
(community_follower).community_id) AS diff
community.id = (community_follower).community_id LIMIT 1)
GROUP BY (community_follower).community_id) AS diff
WHERE
a.community_id = diff.community_id
$$);
a.community_id = diff.community_id $$);
-- 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.
@ -501,7 +427,7 @@ CREATE FUNCTION r.community_aggregates_from_community ()
BEGIN
INSERT INTO community_aggregates (community_id, published)
SELECT
community_id,
id,
published
FROM
new_community;