Find the users which are more likely to become TL3

これで わずかに 効率が向上しました。それでも実行できない場合は、一部の列を削除し、関連する結合とクエリを削除してみてください。

編集
JOIN の種類をようやく理解しました(しばらくぶりです)。この更新されたクエリは はるかに 効率的です。

with
t as (
  select
    CURRENT_TIMESTAMP - ((0 + 100) * (INTERVAL '1 days')) as start,
    CURRENT_TIMESTAMP - (0 * (INTERVAL '1 days')) as end
  ),

-- 過去100日間のトピック数 25%
-- 過去100日間に作成されたトピックの25%の小さい方
-- または 500 (TL3 のシステムデフォルト最大要件)
tclhd AS (
    SELECT LEAST(floor(count(id)*.25)::REAL,500) as all_topics
    FROM topics, t
    WHERE created_at > t.start
        AND archetype = 'regular'
        AND deleted_at is null
    ),

-- 過去100日間の投稿数 25%
-- 過去100日間に作成された投稿の25%の小さい方
-- または 20k (TL3 のシステムデフォルト最大要件)
pclhd AS (
SELECT LEAST(FLOOR(count(id)*.25)::REAL,20000) AS all_posts
FROM t, posts
WHERE posts.created_at > start
    AND posts.deleted_at is null
    AND posts.hidden_at is null
    AND posts.last_editor_id >0  -- Discobot & System を除く
    AND (action_code is null OR action_code != 'assigned')
    ),

-- レベル2ユーザー
tl AS (
SELECT id as user_id, trust_level
FROM users
WHERE trust_level = 2
    ),

-- ユーザー、訪問、投稿閲覧数 過去100日
pr AS (
    SELECT user_id,
        count(1) as visits,
        sum(posts_read) as posts_read
    FROM t, user_visits
    INNER JOIN tl using (user_id)
    WHERE visited_at > t.start
      AND visited_at < t.end
    GROUP BY user_id
    ORDER BY visits DESC
    ),

-- 投稿閲覧数 全期間
prat as (
    select user_id,
        sum(posts_read) as posts_read
    from t, user_visits
    INNER JOIN tl using (user_id)
    group by user_id
    ),

-- 返信したトピック
trt as (
    select user_id,
           count(distinct topic_id) as topic_id
    from t, posts
    INNER JOIN tl using (user_id)
    where posts.created_at > t.start
      and posts.created_at < t.end
    group by user_id
    ),

-- 閲覧したトピック 全期間
tvat as (
    select tv.user_id,
        COUNT(distinct tv.topic_id) AS topic_id
    FROM topic_views tv
    LEFT JOIN topics t on tv.topic_id=t.id
    INNER JOIN tl on tv.user_id=tl.user_id
    WHERE
        t.archetype = 'regular'
        AND t.deleted_at is null
    group by tv.user_id
    ),

-- 閲覧したトピック
tva AS (
SELECT tv.user_id,
    COUNT(distinct tv.topic_id) AS topic_id
FROM t, topic_views tv
    LEFT JOIN topics on topic_id=topics.id
    INNER JOIN tl on tv.user_id=tl.user_id
    WHERE
        topics.archetype = 'regular'
        AND topics.deleted_at is null
        AND viewed_at > t.start
        AND viewed_at < t.end
GROUP BY tv.user_id
    ),

likes AS (
    SELECT user_id,
        likes_given, likes_received
    from user_stats
    INNER JOIN tl using (user_id)
)


SELECT  pr.user_id,
        greatest(50-coalesce(pr.visits,0),0) as "訪問日数ギャップ",
        greatest(10-coalesce(trt.topic_id,0), 0)  as "返信トピックギャップ",
        greatest(tclhd.all_topics-coalesce(tva.topic_id,0),0) AS "閲覧トピックギャップ",
        greatest(200-coalesce(tvat.topic_id,0),0) as "閲覧トピック(AT)ギャップ",
        greatest(pclhd.all_posts - coalesce(pr.posts_read,0),0) as "投稿閲覧ギャップ",
        greatest(500-coalesce(prat.posts_read,0),0) as "投稿閲覧(AT)ギャップ",
        greatest(30-likes.likes_given,0) as "いいね送信ギャップ",
        greatest(20-likes.likes_received,0) as "いいね受信ギャップ"

FROM pclhd, tclhd, pr
left join trt using (user_id)
LEFT JOIN tva USING (user_id)
left join tvat using (user_id)
left join prat using (user_id)
LEFT JOIN likes using (user_id)


ORDER BY
  pr.visits DESC

LIMIT 50
「いいね!」 8