Und hier ist der TL2-Lückenbericht:
with
-- Trust Level 1 Benutzer
tl AS (
SELECT id as user_id, trust_level, last_seen_at
FROM users
WHERE trust_level = 1
),
-- Benutzer, die in den letzten 3 Monaten gesehen wurden + Besuche, gelesene Beiträge, Lesezeit
pr AS (
SELECT user_id,
count(1) as visits,
sum(posts_read) as posts_read,
SUM(time_read)/60 as minutes_reading_time,
DATE(last_seen_at) AS last_seen
FROM user_visits
INNER JOIN tl using (user_id)
WHERE DATE(last_seen_at) >= CURRENT_DATE - INTERVAL '3 month'
GROUP BY user_id, last_seen
ORDER BY visits, last_seen DESC
),
-- Themen, auf die geantwortet wurde
trt AS (
select posts.user_id,
count(distinct topic_id) as replied_count
from posts
INNER JOIN tl using (user_id)
INNER JOIN topics ON topics.id = posts.topic_id
WHERE topics.user_id <> posts.user_id
AND posts.deleted_at IS NULL AND topics.deleted_at IS NULL
-- AND topics.archetype <> 'private_message'
AND archetype = 'regular'
GROUP BY posts.user_id
ORDER BY replied_count DESC
),
-- Themen, die aller Zeiten angesehen wurden
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
),
likes AS (
SELECT user_id,
likes_given, likes_received
from user_stats
INNER JOIN tl using (user_id)
)
SELECT pr.user_id,
pr.last_seen as "Zuletzt gesehen",
-- Tage besucht: 15
greatest(15-coalesce(pr.visits,0),0) as "Tage besucht Lücke",
-- Themenantworten: 3
greatest(3-coalesce(trt.replied_count,0), 0) as "Themenantwort Lücke",
-- Themen eingegeben: 20
greatest(20-coalesce(tvat.topic_id,0),0) as "Themen angesehen Lücke",
-- Beiträge gelesen: 100
greatest(100-coalesce(pr.posts_read,0),0) as "Beiträge gelesen Lücke",
-- Zeit mit Lesen von Beiträgen verbracht: 60min
greatest(60-pr.minutes_reading_time,0) as "Lesezeit Lücke",
-- Likes gegeben: 1
greatest(1-likes.likes_given,0) as "Likes gegeben Lücke",
-- Likes erhalten: 1
greatest(1-likes.likes_received,0) as "Likes erhalten Lücke"
FROM pr
left join trt using (user_id)
left join tvat using (user_id)
LEFT JOIN likes using (user_id)
ORDER BY
pr.visits DESC
LIMIT 500