mirror of
https://github.com/LemmyNet/lemmy.git
synced 2024-11-25 22:01:19 +00:00
fix some things
This commit is contained in:
parent
d67bd5f249
commit
0844a7612a
1 changed files with 214 additions and 288 deletions
|
@ -48,75 +48,72 @@ $$;
|
||||||
-- * `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
|
||||||
|
-- `PERFORM` isn't used because it doesn't allow `WITH`
|
||||||
defs text := $b$
|
defs text := $b$
|
||||||
|
-- Delete
|
||||||
CREATE FUNCTION r.thing_delete_statement ()
|
CREATE FUNCTION r.thing_delete_statement ()
|
||||||
RETURNS TRIGGER
|
RETURNS TRIGGER
|
||||||
LANGUAGE plpgsql
|
LANGUAGE plpgsql
|
||||||
AS $$
|
AS $$
|
||||||
|
DECLARE
|
||||||
|
foo int;
|
||||||
BEGIN
|
BEGIN
|
||||||
PERFORM (
|
WITH combined_transition_tables AS (
|
||||||
WITH
|
|
||||||
combined_transition_tables AS (
|
|
||||||
select_old_table
|
select_old_table
|
||||||
),
|
),
|
||||||
trigger_result AS command
|
trigger_result AS command
|
||||||
SELECT
|
SELECT
|
||||||
1
|
1 INTO foo;
|
||||||
);
|
|
||||||
RETURN NULL;
|
RETURN NULL;
|
||||||
END
|
END $$;
|
||||||
$$;
|
|
||||||
CREATE TRIGGER delete_statement
|
CREATE TRIGGER delete_statement
|
||||||
AFTER DELETE ON thing REFERENCING OLD TABLE AS old_table
|
AFTER DELETE ON thing REFERENCING OLD TABLE AS old_table
|
||||||
FOR EACH STATEMENT
|
FOR EACH STATEMENT
|
||||||
EXECUTE FUNCTION r.thing_delete_statement ( );
|
EXECUTE FUNCTION r.thing_delete_statement ( );
|
||||||
|
-- Insert
|
||||||
CREATE FUNCTION r.thing_insert_statement ( )
|
CREATE FUNCTION r.thing_insert_statement ( )
|
||||||
RETURNS TRIGGER
|
RETURNS TRIGGER
|
||||||
LANGUAGE plpgsql
|
LANGUAGE plpgsql
|
||||||
AS $$
|
AS $$
|
||||||
|
DECLARE
|
||||||
|
foo int;
|
||||||
BEGIN
|
BEGIN
|
||||||
PERFORM (
|
WITH combined_transition_tables AS (
|
||||||
WITH
|
|
||||||
combined_transition_tables AS (
|
|
||||||
select_new_table
|
select_new_table
|
||||||
),
|
),
|
||||||
trigger_result AS command
|
trigger_result AS command
|
||||||
SELECT
|
SELECT
|
||||||
1
|
1 INTO foo;
|
||||||
);
|
|
||||||
RETURN NULL;
|
RETURN NULL;
|
||||||
END
|
END $$;
|
||||||
$$;
|
|
||||||
CREATE TRIGGER insert_statement
|
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
|
FOR EACH STATEMENT
|
||||||
EXECUTE FUNCTION r.thing_insert_statement ( );
|
EXECUTE FUNCTION r.thing_insert_statement ( );
|
||||||
|
-- Update
|
||||||
CREATE FUNCTION r.thing_update_statement ( )
|
CREATE FUNCTION r.thing_update_statement ( )
|
||||||
RETURNS TRIGGER
|
RETURNS TRIGGER
|
||||||
LANGUAGE plpgsql
|
LANGUAGE plpgsql
|
||||||
AS $$
|
AS $$
|
||||||
|
DECLARE
|
||||||
|
foo int;
|
||||||
BEGIN
|
BEGIN
|
||||||
PERFORM (
|
WITH combined_transition_tables AS (
|
||||||
WITH
|
|
||||||
combined_transition_tables AS (
|
|
||||||
select_old_table
|
select_old_table
|
||||||
UNION ALL
|
UNION ALL select_new_table
|
||||||
select_new_table
|
|
||||||
),
|
),
|
||||||
trigger_result AS command
|
trigger_result AS command
|
||||||
SELECT
|
SELECT
|
||||||
1
|
1 INTO foo;
|
||||||
);
|
|
||||||
RETURN NULL;
|
RETURN NULL;
|
||||||
END
|
END $$;
|
||||||
$$;
|
|
||||||
CREATE TRIGGER update_statement
|
CREATE TRIGGER update_statement
|
||||||
AFTER UPDATE ON thing REFERENCING OLD TABLE AS old_table NEW TABLE AS new_table
|
AFTER UPDATE ON thing REFERENCING OLD TABLE AS old_table NEW TABLE AS new_table
|
||||||
FOR EACH STATEMENT
|
FOR EACH STATEMENT
|
||||||
|
@ -124,11 +121,11 @@ DECLARE
|
||||||
$b$;
|
$b$;
|
||||||
BEGIN
|
BEGIN
|
||||||
defs := replace(defs, 'select_old_table', $$
|
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', $$
|
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, 'thing', table_name);
|
||||||
defs := replace(defs, 'command', format('(%s)', command));
|
defs := replace(defs, 'command', format('(%s)', command));
|
||||||
EXECUTE defs;
|
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 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 (
|
|
||||||
UPDATE
|
|
||||||
thing_aggregates AS a
|
thing_aggregates AS a
|
||||||
SET
|
SET
|
||||||
score = a.score + diff.upvotes - diff.downvotes,
|
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)
|
||||||
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 (
|
FROM (
|
||||||
SELECT
|
SELECT
|
||||||
(thing_like).thing_id,
|
(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
|
||||||
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
|
|
||||||
WHERE
|
WHERE
|
||||||
a.thing_id = diff.thing_id
|
a.thing_id = diff.thing_id
|
||||||
RETURNING
|
RETURNING
|
||||||
creator_id_from_thing_aggregates (a.*) AS creator_id,
|
creator_id_from_thing_aggregates (a.*) AS creator_id, diff.upvotes - diff.downvotes AS score)
|
||||||
diff.upvotes - diff.downvotes AS score)
|
|
||||||
UPDATE
|
UPDATE
|
||||||
person_aggregates AS a
|
person_aggregates AS a
|
||||||
SET
|
SET
|
||||||
thing_score = a.thing_score + diff.score
|
thing_score = a.thing_score + diff.score FROM (
|
||||||
FROM (
|
|
||||||
SELECT
|
SELECT
|
||||||
creator_id,
|
creator_id, sum(score) AS score FROM target_diff GROUP BY creator_id) AS diff
|
||||||
sum(score) AS score
|
|
||||||
FROM
|
|
||||||
target_diff
|
|
||||||
GROUP BY
|
|
||||||
creator_id) AS diff
|
|
||||||
WHERE
|
WHERE
|
||||||
a.person_id = diff.creator_id
|
a.person_id = diff.creator_id $$);
|
||||||
$$);
|
$b$,
|
||||||
|
'thing',
|
||||||
|
table_name);
|
||||||
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
|
|
||||||
combined_transition_tables
|
|
||||||
AS (count_diff bigint,
|
|
||||||
comment comment)
|
|
||||||
WHERE
|
WHERE
|
||||||
NOT ((comment).deleted OR (comment).removed)
|
NOT ((comment).deleted
|
||||||
GROUP BY
|
OR (comment).removed)
|
||||||
GROUPING SETS ((comment).post_id,
|
GROUP BY GROUPING SETS ((comment).post_id, (comment).creator_id, (comment).local)),
|
||||||
(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,8 +225,7 @@ 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
|
||||||
|
@ -264,8 +234,7 @@ unused_site_aggregates_update_result AS (
|
||||||
FROM
|
FROM
|
||||||
comment_group
|
comment_group
|
||||||
WHERE
|
WHERE
|
||||||
comment_group.local
|
comment_group.local),
|
||||||
),
|
|
||||||
post_diff AS (
|
post_diff AS (
|
||||||
UPDATE
|
UPDATE
|
||||||
post_aggregates AS a
|
post_aggregates AS a
|
||||||
|
@ -311,8 +280,7 @@ SET
|
||||||
comments = a.comments + diff.comments
|
comments = a.comments + diff.comments
|
||||||
FROM (
|
FROM (
|
||||||
SELECT
|
SELECT
|
||||||
community_id,
|
community_id, sum(comments)
|
||||||
sum(comments)
|
|
||||||
FROM
|
FROM
|
||||||
post_diff
|
post_diff
|
||||||
WHERE
|
WHERE
|
||||||
|
@ -320,83 +288,51 @@ FROM (
|
||||||
GROUP BY
|
GROUP BY
|
||||||
community_id) AS diff
|
community_id) AS diff
|
||||||
WHERE
|
WHERE
|
||||||
a.community_id = diff.community_id
|
a.community_id = diff.community_id $$);
|
||||||
$$);
|
|
||||||
|
|
||||||
CALL r.create_triggers('post', $$
|
CALL r.create_triggers ('post', $$ WITH post_group AS (
|
||||||
WITH post_group AS (
|
|
||||||
SELECT
|
SELECT
|
||||||
(post).community_id,
|
(post).community_id, (post).creator_id, (post).local, sum(count_diff) AS posts FROM combined_transition_tables
|
||||||
(post).creator_id,
|
|
||||||
(post).local,
|
|
||||||
sum(count_diff) AS posts
|
|
||||||
FROM
|
|
||||||
combined_post_transition_tables
|
|
||||||
AS (count_diff bigint,
|
|
||||||
post post)
|
|
||||||
WHERE
|
WHERE
|
||||||
NOT ((post).deleted OR (post).removed)
|
NOT ((post).deleted
|
||||||
GROUP BY
|
OR (post).removed)
|
||||||
GROUPING SETS ((post).community_id,
|
GROUP BY GROUPING SETS ((post).community_id, (post).creator_id, (post).local)
|
||||||
(post).creator_id,
|
), unused_person_aggregates_update_result AS ( UPDATE
|
||||||
(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
|
|
||||||
post_group
|
|
||||||
WHERE
|
WHERE
|
||||||
a.person_id = post_group.creator_id
|
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
|
site_aggregates AS a
|
||||||
SET
|
SET
|
||||||
posts = a.posts + post_group.posts
|
posts = a.posts + post_group.posts FROM post_group
|
||||||
FROM
|
|
||||||
post_group
|
|
||||||
WHERE
|
WHERE
|
||||||
post_group.local)
|
post_group.local)
|
||||||
UPDATE
|
UPDATE
|
||||||
community_aggregates AS a
|
community_aggregates AS a
|
||||||
SET
|
SET
|
||||||
posts = a.posts + post_group.posts
|
posts = a.posts + post_group.posts FROM post_group
|
||||||
FROM
|
|
||||||
post_group
|
|
||||||
WHERE
|
WHERE
|
||||||
a.community_id = post_group.community_id
|
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
|
sum(count_diff) AS communities FROM combined_transition_tables
|
||||||
FROM
|
WHERE (community).local
|
||||||
combined_transition_tables
|
AND NOT ((community).deleted
|
||||||
AS (count_diff bigint, community community)
|
OR (community).removed)) AS diff $$);
|
||||||
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
|
sum(count_diff) AS users FROM combined_transition_tables
|
||||||
FROM
|
WHERE (person).local) AS diff $$);
|
||||||
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,
|
(community_follower).community_id, sum(count_diff) AS subscribers FROM combined_transition_tables
|
||||||
sum(count_diff) AS subscribers
|
|
||||||
FROM
|
|
||||||
combine_transition_tables
|
|
||||||
AS (count_diff bigint, community_follower community_follower)
|
|
||||||
WHERE (
|
WHERE (
|
||||||
SELECT
|
SELECT
|
||||||
local
|
local
|
||||||
FROM
|
FROM community
|
||||||
community
|
|
||||||
WHERE
|
WHERE
|
||||||
community.id = (community_follower).community_id
|
community.id = (community_follower).community_id LIMIT 1)
|
||||||
LIMIT 1)
|
GROUP BY (community_follower).community_id) AS diff
|
||||||
GROUP BY
|
|
||||||
(community_follower).community_id) AS diff
|
|
||||||
WHERE
|
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.
|
-- 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;
|
||||||
|
|
Loading…
Reference in a new issue