mirror of https://github.com/zulip/zulip.git
activity: Speed up the main query in /activity.
This commit is contained in:
parent
72d6ff3c3b
commit
f1ceab69c9
|
@ -543,107 +543,71 @@ def realm_summary_table(realm_minutes: Dict[str, float]) -> str:
|
||||||
realm.string_id,
|
realm.string_id,
|
||||||
realm.date_created,
|
realm.date_created,
|
||||||
realm.plan_type,
|
realm.plan_type,
|
||||||
coalesce(user_counts.dau_count, 0) dau_count,
|
coalesce(wau_table.value, 0) wau_count,
|
||||||
coalesce(wau_counts.wau_count, 0) wau_count,
|
coalesce(dau_table.value, 0) dau_count,
|
||||||
(
|
coalesce(user_count_table.value, 0) user_profile_count,
|
||||||
|
coalesce(bot_count_table.value, 0) bot_count
|
||||||
|
FROM
|
||||||
|
zerver_realm as realm
|
||||||
|
LEFT OUTER JOIN (
|
||||||
SELECT
|
SELECT
|
||||||
count(*)
|
value _14day_active_humans,
|
||||||
FROM zerver_userprofile up
|
realm_id
|
||||||
WHERE up.realm_id = realm.id
|
from
|
||||||
AND is_active
|
analytics_realmcount
|
||||||
AND not is_bot
|
|
||||||
) user_profile_count,
|
|
||||||
(
|
|
||||||
SELECT
|
|
||||||
count(*)
|
|
||||||
FROM zerver_userprofile up
|
|
||||||
WHERE up.realm_id = realm.id
|
|
||||||
AND is_active
|
|
||||||
AND is_bot
|
|
||||||
) bot_count
|
|
||||||
FROM zerver_realm realm
|
|
||||||
LEFT OUTER JOIN
|
|
||||||
(
|
|
||||||
SELECT
|
|
||||||
up.realm_id realm_id,
|
|
||||||
count(distinct(ua.user_profile_id)) dau_count
|
|
||||||
FROM zerver_useractivity ua
|
|
||||||
JOIN zerver_userprofile up
|
|
||||||
ON up.id = ua.user_profile_id
|
|
||||||
WHERE
|
WHERE
|
||||||
up.is_active
|
property = 'realm_active_humans::day'
|
||||||
AND (not up.is_bot)
|
AND end_time > now() - interval '25 hours'
|
||||||
AND
|
) as _14day_active_humans_table ON realm.id = _14day_active_humans_table.realm_id
|
||||||
query in (
|
LEFT OUTER JOIN (
|
||||||
'/json/send_message',
|
|
||||||
'send_message_backend',
|
|
||||||
'/api/v1/send_message',
|
|
||||||
'/json/update_pointer',
|
|
||||||
'/json/users/me/pointer',
|
|
||||||
'update_pointer_backend'
|
|
||||||
)
|
|
||||||
AND
|
|
||||||
last_visit > now() - interval '1 day'
|
|
||||||
GROUP BY realm_id
|
|
||||||
) user_counts
|
|
||||||
ON user_counts.realm_id = realm.id
|
|
||||||
LEFT OUTER JOIN
|
|
||||||
(
|
|
||||||
SELECT
|
SELECT
|
||||||
realm_id,
|
value,
|
||||||
count(*) wau_count
|
realm_id
|
||||||
FROM (
|
from
|
||||||
SELECT
|
analytics_realmcount
|
||||||
realm.id as realm_id,
|
WHERE
|
||||||
up.delivery_email
|
property = '7day_actives::day'
|
||||||
FROM zerver_useractivity ua
|
AND end_time > now() - interval '25 hours'
|
||||||
JOIN zerver_userprofile up
|
) as wau_table ON realm.id = wau_table.realm_id
|
||||||
ON up.id = ua.user_profile_id
|
LEFT OUTER JOIN (
|
||||||
JOIN zerver_realm realm
|
SELECT
|
||||||
ON realm.id = up.realm_id
|
value,
|
||||||
WHERE up.is_active
|
realm_id
|
||||||
AND (not up.is_bot)
|
from
|
||||||
AND
|
analytics_realmcount
|
||||||
ua.query in (
|
WHERE
|
||||||
'/json/send_message',
|
property = '1day_actives::day'
|
||||||
'send_message_backend',
|
AND end_time > now() - interval '25 hours'
|
||||||
'/api/v1/send_message',
|
) as dau_table ON realm.id = dau_table.realm_id
|
||||||
'/json/update_pointer',
|
LEFT OUTER JOIN (
|
||||||
'/json/users/me/pointer',
|
SELECT
|
||||||
'update_pointer_backend'
|
value,
|
||||||
)
|
realm_id
|
||||||
GROUP by realm.id, up.delivery_email
|
from
|
||||||
HAVING max(last_visit) > now() - interval '7 day'
|
analytics_realmcount
|
||||||
) as wau_users
|
WHERE
|
||||||
GROUP BY realm_id
|
property = 'active_users_audit:is_bot:day'
|
||||||
) wau_counts
|
AND subgroup = 'false'
|
||||||
ON wau_counts.realm_id = realm.id
|
AND end_time > now() - interval '25 hours'
|
||||||
|
) as user_count_table ON realm.id = user_count_table.realm_id
|
||||||
|
LEFT OUTER JOIN (
|
||||||
|
SELECT
|
||||||
|
value,
|
||||||
|
realm_id
|
||||||
|
from
|
||||||
|
analytics_realmcount
|
||||||
|
WHERE
|
||||||
|
property = 'active_users_audit:is_bot:day'
|
||||||
|
AND subgroup = 'true'
|
||||||
|
AND end_time > now() - interval '25 hours'
|
||||||
|
) as bot_count_table ON realm.id = bot_count_table.realm_id
|
||||||
WHERE
|
WHERE
|
||||||
realm.plan_type = 3
|
_14day_active_humans IS NOT NULL
|
||||||
OR
|
or realm.plan_type = 3
|
||||||
EXISTS (
|
ORDER BY
|
||||||
SELECT *
|
dau_count DESC,
|
||||||
FROM zerver_useractivity ua
|
string_id ASC
|
||||||
JOIN zerver_userprofile up
|
''')
|
||||||
ON up.id = ua.user_profile_id
|
|
||||||
WHERE
|
|
||||||
up.realm_id = realm.id
|
|
||||||
AND up.is_active
|
|
||||||
AND (not up.is_bot)
|
|
||||||
AND
|
|
||||||
query in (
|
|
||||||
'/json/send_message',
|
|
||||||
'/api/v1/send_message',
|
|
||||||
'send_message_backend',
|
|
||||||
'/json/update_pointer',
|
|
||||||
'/json/users/me/pointer',
|
|
||||||
'update_pointer_backend'
|
|
||||||
)
|
|
||||||
AND
|
|
||||||
last_visit > now() - interval '2 week'
|
|
||||||
)
|
|
||||||
ORDER BY dau_count DESC, string_id ASC
|
|
||||||
''')
|
|
||||||
|
|
||||||
cursor = connection.cursor()
|
cursor = connection.cursor()
|
||||||
cursor.execute(query)
|
cursor.execute(query)
|
||||||
|
|
Loading…
Reference in New Issue