mirror of
https://github.com/LemmyNet/lemmy.git
synced 2024-11-14 16:34:01 +00:00
be1389420b
* SQL format checking, 1. * SQL format checking, 2. * SQL format checking, 3. * SQL format checking, 4. * SQL format checking, 5. * Running pg_format * Getting rid of comment. * Upping pg_format version. * Using git ls-files for sql format check. * Fixing sql lints. * Addressing PR comments.
162 lines
3.5 KiB
PL/PgSQL
162 lines
3.5 KiB
PL/PgSQL
-- Add monthly and half yearly active columns for site and community aggregates
|
|
-- These columns don't need to be updated with a trigger, so they're saved daily via queries
|
|
ALTER TABLE site_aggregates
|
|
ADD COLUMN users_active_day bigint NOT NULL DEFAULT 0;
|
|
|
|
ALTER TABLE site_aggregates
|
|
ADD COLUMN users_active_week bigint NOT NULL DEFAULT 0;
|
|
|
|
ALTER TABLE site_aggregates
|
|
ADD COLUMN users_active_month bigint NOT NULL DEFAULT 0;
|
|
|
|
ALTER TABLE site_aggregates
|
|
ADD COLUMN users_active_half_year bigint NOT NULL DEFAULT 0;
|
|
|
|
ALTER TABLE community_aggregates
|
|
ADD COLUMN users_active_day bigint NOT NULL DEFAULT 0;
|
|
|
|
ALTER TABLE community_aggregates
|
|
ADD COLUMN users_active_week bigint NOT NULL DEFAULT 0;
|
|
|
|
ALTER TABLE community_aggregates
|
|
ADD COLUMN users_active_month bigint NOT NULL DEFAULT 0;
|
|
|
|
ALTER TABLE community_aggregates
|
|
ADD COLUMN users_active_half_year bigint NOT NULL DEFAULT 0;
|
|
|
|
CREATE OR REPLACE FUNCTION site_aggregates_activity (i text)
|
|
RETURNS int
|
|
LANGUAGE plpgsql
|
|
AS $$
|
|
DECLARE
|
|
count_ integer;
|
|
BEGIN
|
|
SELECT
|
|
count(*) INTO count_
|
|
FROM (
|
|
SELECT
|
|
c.creator_id
|
|
FROM
|
|
comment c
|
|
INNER JOIN user_ u ON c.creator_id = u.id
|
|
WHERE
|
|
c.published > ('now'::timestamp - i::interval)
|
|
AND u.local = TRUE
|
|
UNION
|
|
SELECT
|
|
p.creator_id
|
|
FROM
|
|
post p
|
|
INNER JOIN user_ u ON p.creator_id = u.id
|
|
WHERE
|
|
p.published > ('now'::timestamp - i::interval)
|
|
AND u.local = TRUE) a;
|
|
RETURN count_;
|
|
END;
|
|
$$;
|
|
|
|
UPDATE
|
|
site_aggregates
|
|
SET
|
|
users_active_day = (
|
|
SELECT
|
|
*
|
|
FROM
|
|
site_aggregates_activity ('1 day'));
|
|
|
|
UPDATE
|
|
site_aggregates
|
|
SET
|
|
users_active_week = (
|
|
SELECT
|
|
*
|
|
FROM
|
|
site_aggregates_activity ('1 week'));
|
|
|
|
UPDATE
|
|
site_aggregates
|
|
SET
|
|
users_active_month = (
|
|
SELECT
|
|
*
|
|
FROM
|
|
site_aggregates_activity ('1 month'));
|
|
|
|
UPDATE
|
|
site_aggregates
|
|
SET
|
|
users_active_half_year = (
|
|
SELECT
|
|
*
|
|
FROM
|
|
site_aggregates_activity ('6 months'));
|
|
|
|
CREATE OR REPLACE FUNCTION community_aggregates_activity (i text)
|
|
RETURNS TABLE (
|
|
count_ bigint,
|
|
community_id_ integer)
|
|
LANGUAGE plpgsql
|
|
AS $$
|
|
BEGIN
|
|
RETURN query
|
|
SELECT
|
|
count(*),
|
|
community_id
|
|
FROM (
|
|
SELECT
|
|
c.creator_id,
|
|
p.community_id
|
|
FROM
|
|
comment c
|
|
INNER JOIN post p ON c.post_id = p.id
|
|
WHERE
|
|
c.published > ('now'::timestamp - i::interval)
|
|
UNION
|
|
SELECT
|
|
p.creator_id,
|
|
p.community_id
|
|
FROM
|
|
post p
|
|
WHERE
|
|
p.published > ('now'::timestamp - i::interval)) a
|
|
GROUP BY
|
|
community_id;
|
|
END;
|
|
$$;
|
|
|
|
UPDATE
|
|
community_aggregates ca
|
|
SET
|
|
users_active_day = mv.count_
|
|
FROM
|
|
community_aggregates_activity ('1 day') mv
|
|
WHERE
|
|
ca.community_id = mv.community_id_;
|
|
|
|
UPDATE
|
|
community_aggregates ca
|
|
SET
|
|
users_active_week = mv.count_
|
|
FROM
|
|
community_aggregates_activity ('1 week') mv
|
|
WHERE
|
|
ca.community_id = mv.community_id_;
|
|
|
|
UPDATE
|
|
community_aggregates ca
|
|
SET
|
|
users_active_month = mv.count_
|
|
FROM
|
|
community_aggregates_activity ('1 month') mv
|
|
WHERE
|
|
ca.community_id = mv.community_id_;
|
|
|
|
UPDATE
|
|
community_aggregates ca
|
|
SET
|
|
users_active_half_year = mv.count_
|
|
FROM
|
|
community_aggregates_activity ('6 months') mv
|
|
WHERE
|
|
ca.community_id = mv.community_id_;
|
|
|