lemmy/migrations/2024-11-21-195004_add_report_count/up.sql
Dessalines ba3d574d92
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.
2024-11-25 11:24:57 +01:00

80 lines
1.5 KiB
SQL

-- 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;