Add report_counts to post and comment aggregate tables. (#5219)
* Add report_counts to post and comment aggregate tables. - This adds a report_count and unresolved_report_count to the post and comment aggregate tables. - Useful for front-ends wishing to show report links. - Fixes #4163 * Updating the historical counts. * Switching from bigint to smallint. * Using dullbananas create_trigger function.
This commit is contained in:
parent
41bd830389
commit
ba3d574d92
9 changed files with 162 additions and 0 deletions
|
@ -384,6 +384,44 @@ END;
|
|||
|
||||
$$);
|
||||
|
||||
CALL r.create_triggers ('post_report', $$
|
||||
BEGIN
|
||||
UPDATE
|
||||
post_aggregates AS a
|
||||
SET
|
||||
report_count = a.report_count + diff.report_count, unresolved_report_count = a.unresolved_report_count + diff.unresolved_report_count
|
||||
FROM (
|
||||
SELECT
|
||||
(post_report).post_id, coalesce(sum(count_diff), 0) AS report_count, coalesce(sum(count_diff) FILTER (WHERE NOT (post_report).resolved), 0) AS unresolved_report_count
|
||||
FROM select_old_and_new_rows AS old_and_new_rows GROUP BY (post_report).post_id) AS diff
|
||||
WHERE (diff.report_count, diff.unresolved_report_count) != (0, 0)
|
||||
AND a.post_id = diff.post_id;
|
||||
|
||||
RETURN NULL;
|
||||
|
||||
END;
|
||||
|
||||
$$);
|
||||
|
||||
CALL r.create_triggers ('comment_report', $$
|
||||
BEGIN
|
||||
UPDATE
|
||||
comment_aggregates AS a
|
||||
SET
|
||||
report_count = a.report_count + diff.report_count, unresolved_report_count = a.unresolved_report_count + diff.unresolved_report_count
|
||||
FROM (
|
||||
SELECT
|
||||
(comment_report).comment_id, coalesce(sum(count_diff), 0) AS report_count, coalesce(sum(count_diff) FILTER (WHERE NOT (comment_report).resolved), 0) AS unresolved_report_count
|
||||
FROM select_old_and_new_rows AS old_and_new_rows GROUP BY (comment_report).comment_id) AS diff
|
||||
WHERE (diff.report_count, diff.unresolved_report_count) != (0, 0)
|
||||
AND a.comment_id = diff.comment_id;
|
||||
|
||||
RETURN NULL;
|
||||
|
||||
END;
|
||||
|
||||
$$);
|
||||
|
||||
-- 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.
|
||||
CREATE FUNCTION r.comment_aggregates_from_comment ()
|
||||
|
|
|
@ -39,6 +39,8 @@ pub struct CommentAggregates {
|
|||
pub hot_rank: f64,
|
||||
#[serde(skip)]
|
||||
pub controversy_rank: f64,
|
||||
pub report_count: i16,
|
||||
pub unresolved_report_count: i16,
|
||||
}
|
||||
|
||||
#[derive(PartialEq, Debug, Serialize, Deserialize, Clone)]
|
||||
|
@ -146,6 +148,8 @@ pub struct PostAggregates {
|
|||
/// A rank that amplifies smaller communities
|
||||
#[serde(skip)]
|
||||
pub scaled_rank: f64,
|
||||
pub report_count: i16,
|
||||
pub unresolved_report_count: i16,
|
||||
}
|
||||
|
||||
#[derive(PartialEq, Eq, Debug, Serialize, Deserialize, Clone)]
|
||||
|
|
|
@ -130,6 +130,8 @@ diesel::table! {
|
|||
child_count -> Int4,
|
||||
hot_rank -> Float8,
|
||||
controversy_rank -> Float8,
|
||||
report_count -> Int2,
|
||||
unresolved_report_count -> Int2,
|
||||
}
|
||||
}
|
||||
|
||||
|
@ -777,6 +779,8 @@ diesel::table! {
|
|||
controversy_rank -> Float8,
|
||||
instance_id -> Int4,
|
||||
scaled_rank -> Float8,
|
||||
report_count -> Int2,
|
||||
unresolved_report_count -> Int2,
|
||||
}
|
||||
}
|
||||
|
||||
|
|
|
@ -444,6 +444,8 @@ mod tests {
|
|||
child_count: 0,
|
||||
hot_rank: RANK_DEFAULT,
|
||||
controversy_rank: 0.0,
|
||||
report_count: 2,
|
||||
unresolved_report_count: 2,
|
||||
},
|
||||
my_vote: None,
|
||||
resolver: None,
|
||||
|
@ -511,6 +513,10 @@ mod tests {
|
|||
.updated = read_jessica_report_view_after_resolve
|
||||
.comment_report
|
||||
.updated;
|
||||
expected_jessica_report_view_after_resolve
|
||||
.counts
|
||||
.unresolved_report_count = 1;
|
||||
expected_sara_report_view.counts.unresolved_report_count = 1;
|
||||
expected_jessica_report_view_after_resolve.resolver = Some(Person {
|
||||
id: inserted_timmy.id,
|
||||
name: inserted_timmy.name.clone(),
|
||||
|
|
|
@ -1068,6 +1068,8 @@ mod tests {
|
|||
child_count: 5,
|
||||
hot_rank: RANK_DEFAULT,
|
||||
controversy_rank: 0.0,
|
||||
report_count: 0,
|
||||
unresolved_report_count: 0,
|
||||
},
|
||||
})
|
||||
}
|
||||
|
|
|
@ -232,6 +232,7 @@ mod tests {
|
|||
structs::LocalUserView,
|
||||
};
|
||||
use lemmy_db_schema::{
|
||||
aggregates::structs::PostAggregates,
|
||||
assert_length,
|
||||
source::{
|
||||
community::{Community, CommunityInsertForm, CommunityModerator, CommunityModeratorForm},
|
||||
|
@ -336,6 +337,10 @@ mod tests {
|
|||
let read_jessica_report_view =
|
||||
PostReportView::read(pool, inserted_jessica_report.id, inserted_timmy.id).await?;
|
||||
|
||||
// Make sure the triggers are reading the aggregates correctly.
|
||||
let agg_1 = PostAggregates::read(pool, inserted_post.id).await?;
|
||||
let agg_2 = PostAggregates::read(pool, inserted_post_2.id).await?;
|
||||
|
||||
assert_eq!(
|
||||
read_jessica_report_view.post_report,
|
||||
inserted_jessica_report
|
||||
|
@ -346,6 +351,10 @@ mod tests {
|
|||
assert_eq!(read_jessica_report_view.post_creator.id, inserted_timmy.id);
|
||||
assert_eq!(read_jessica_report_view.my_vote, None);
|
||||
assert_eq!(read_jessica_report_view.resolver, None);
|
||||
assert_eq!(agg_1.report_count, 1);
|
||||
assert_eq!(agg_1.unresolved_report_count, 1);
|
||||
assert_eq!(agg_2.report_count, 1);
|
||||
assert_eq!(agg_2.unresolved_report_count, 1);
|
||||
|
||||
// Do a batch read of timmys reports
|
||||
let reports = PostReportQuery::default().list(pool, &timmy_view).await?;
|
||||
|
@ -379,6 +388,16 @@ mod tests {
|
|||
Some(inserted_timmy.id)
|
||||
);
|
||||
|
||||
// Make sure the unresolved_post report got decremented in the trigger
|
||||
let agg_2 = PostAggregates::read(pool, inserted_post_2.id).await?;
|
||||
assert_eq!(agg_2.report_count, 1);
|
||||
assert_eq!(agg_2.unresolved_report_count, 0);
|
||||
|
||||
// Make sure the other unresolved report isn't changed
|
||||
let agg_1 = PostAggregates::read(pool, inserted_post.id).await?;
|
||||
assert_eq!(agg_1.report_count, 1);
|
||||
assert_eq!(agg_1.unresolved_report_count, 1);
|
||||
|
||||
// Do a batch read of timmys reports
|
||||
// It should only show saras, which is unresolved
|
||||
let reports_after_resolve = PostReportQuery {
|
||||
|
|
|
@ -1738,6 +1738,8 @@ mod tests {
|
|||
community_id: inserted_post.community_id,
|
||||
creator_id: inserted_post.creator_id,
|
||||
instance_id: data.inserted_instance.id,
|
||||
report_count: 0,
|
||||
unresolved_report_count: 0,
|
||||
},
|
||||
subscribed: SubscribedType::NotSubscribed,
|
||||
read: false,
|
||||
|
|
8
migrations/2024-11-21-195004_add_report_count/down.sql
Normal file
8
migrations/2024-11-21-195004_add_report_count/down.sql
Normal file
|
@ -0,0 +1,8 @@
|
|||
ALTER TABLE post_aggregates
|
||||
DROP COLUMN report_count,
|
||||
DROP COLUMN unresolved_report_count;
|
||||
|
||||
ALTER TABLE comment_aggregates
|
||||
DROP COLUMN report_count,
|
||||
DROP COLUMN unresolved_report_count;
|
||||
|
79
migrations/2024-11-21-195004_add_report_count/up.sql
Normal file
79
migrations/2024-11-21-195004_add_report_count/up.sql
Normal file
|
@ -0,0 +1,79 @@
|
|||
-- Adding report_count and unresolved_report_count
|
||||
-- to the post and comment aggregate tables
|
||||
ALTER TABLE post_aggregates
|
||||
ADD COLUMN report_count smallint NOT NULL DEFAULT 0,
|
||||
ADD COLUMN unresolved_report_count smallint NOT NULL DEFAULT 0;
|
||||
|
||||
ALTER TABLE comment_aggregates
|
||||
ADD COLUMN report_count smallint NOT NULL DEFAULT 0,
|
||||
ADD COLUMN unresolved_report_count smallint NOT NULL DEFAULT 0;
|
||||
|
||||
-- Update the historical counts
|
||||
-- Posts
|
||||
UPDATE
|
||||
post_aggregates AS a
|
||||
SET
|
||||
report_count = cnt.count
|
||||
FROM (
|
||||
SELECT
|
||||
post_id,
|
||||
count(*) AS count
|
||||
FROM
|
||||
post_report
|
||||
GROUP BY
|
||||
post_id) cnt
|
||||
WHERE
|
||||
a.post_id = cnt.post_id;
|
||||
|
||||
-- The unresolved
|
||||
UPDATE
|
||||
post_aggregates AS a
|
||||
SET
|
||||
unresolved_report_count = cnt.count
|
||||
FROM (
|
||||
SELECT
|
||||
post_id,
|
||||
count(*) AS count
|
||||
FROM
|
||||
post_report
|
||||
WHERE
|
||||
resolved = 'f'
|
||||
GROUP BY
|
||||
post_id) cnt
|
||||
WHERE
|
||||
a.post_id = cnt.post_id;
|
||||
|
||||
-- Comments
|
||||
UPDATE
|
||||
comment_aggregates AS a
|
||||
SET
|
||||
report_count = cnt.count
|
||||
FROM (
|
||||
SELECT
|
||||
comment_id,
|
||||
count(*) AS count
|
||||
FROM
|
||||
comment_report
|
||||
GROUP BY
|
||||
comment_id) cnt
|
||||
WHERE
|
||||
a.comment_id = cnt.comment_id;
|
||||
|
||||
-- The unresolved
|
||||
UPDATE
|
||||
comment_aggregates AS a
|
||||
SET
|
||||
unresolved_report_count = cnt.count
|
||||
FROM (
|
||||
SELECT
|
||||
comment_id,
|
||||
count(*) AS count
|
||||
FROM
|
||||
comment_report
|
||||
WHERE
|
||||
resolved = 'f'
|
||||
GROUP BY
|
||||
comment_id) cnt
|
||||
WHERE
|
||||
a.comment_id = cnt.comment_id;
|
||||
|
Loading…
Reference in a new issue