Find the users which are more likely to become TL3

Questo è leggermente più efficiente. Se ancora non funziona, puoi provare a rimuovere alcune colonne, con i relativi join e query.

MODIFICA Ok, finalmente ho capito i miei tipi di join (è passato un po’ di tempo). Questa query aggiornata è molto più efficiente

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

-- Conteggio argomenti ultimi 100 giorni 25%
-- Minore del 25% degli argomenti creati negli ultimi 100 giorni 
-- O 500, il requisito massimo predefinito del sistema per 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
  ),

-- Conteggio post ultimi 100 giorni 25%
-- Minore del 25% dei post creati negli ultimi 100 giorni 
-- O 20k, il requisito massimo predefinito del sistema per 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  -- Ometti Discobot e Sistema
    AND (action_code is null OR action_code != 'assigned')
  ),

-- Utenti Trust Level 2
tl AS (
SELECT id as user_id, trust_level
FROM users
WHERE trust_level = 2
  ),

-- Utenti, visite e post letti ultimi 100 giorni
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
  ),

-- Post letti in assoluto
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
  ),

-- Argomenti a cui si è risposto
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
  ),

-- Argomenti visualizzati in assoluto
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
  ),

-- Argomenti visualizzati
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 "Gap visite",
        greatest(10-coalesce(trt.topic_id,0), 0)  as "Gap risposte argomento",
        greatest(tclhd.all_topics-coalesce(tva.topic_id,0),0) AS "Gap argomenti visualizzati",
        greatest(200-coalesce(tvat.topic_id,0),0) as "Gap argomenti visualizzati (AT)",
        greatest(pclhd.all_posts - coalesce(pr.posts_read,0),0) as "Gap post letti",
        greatest(500-coalesce(prat.posts_read,0),0) as "Gap post letti (AT)",
        greatest(30-likes.likes_given,0) as "Gap like dati",
        greatest(20-likes.likes_received,0) as "Gap like ricevuti"

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 Mi Piace