mirror of
https://github.com/discourse/discourse.git
synced 2025-02-25 18:55:32 -06:00
PERF: Optimize query for finding users with unread chat messages (#29964)
Using CTEs and DISTINCT ON to: - Pre-filter active users with correct preferences - Get only first unread message per channel - Eliminate redundant joins and message scanning This reduces the query execution time by limiting message scanning and joins to only relevant users and messages. Internal ref t/142836 & t/139517
This commit is contained in:
parent
01af75c60b
commit
8f8d88afac
@ -30,38 +30,43 @@ module Chat
|
||||
if Chat.allowed_group_ids.include?(Group::AUTO_GROUPS[:everyone])
|
||||
""
|
||||
else
|
||||
"JOIN group_users ON group_users.user_id = users.id AND group_users.group_id IN (#{Chat.allowed_group_ids.join(",")})"
|
||||
"JOIN group_users gu ON gu.user_id = u.id AND gu.group_id IN (#{Chat.allowed_group_ids.join(",")})"
|
||||
end
|
||||
|
||||
DB.query_single <<~SQL
|
||||
SELECT uccm.user_id
|
||||
FROM user_chat_channel_memberships uccm
|
||||
JOIN users ON users.id = uccm.user_id
|
||||
JOIN user_options ON user_options.user_id = users.id
|
||||
#{groups_join_sql}
|
||||
JOIN chat_channels ON chat_channels.id = uccm.chat_channel_id
|
||||
JOIN chat_messages ON chat_messages.chat_channel_id = chat_channels.id
|
||||
JOIN users sender ON sender.id = chat_messages.user_id
|
||||
LEFT JOIN chat_mentions ON chat_mentions.chat_message_id = chat_messages.id
|
||||
LEFT JOIN chat_mention_notifications cmn ON cmn.chat_mention_id = chat_mentions.id
|
||||
LEFT JOIN notifications ON notifications.id = cmn.notification_id AND notifications.user_id = uccm.user_id
|
||||
WHERE NOT uccm.muted
|
||||
AND (uccm.last_read_message_id IS NULL OR uccm.last_read_message_id < chat_messages.id)
|
||||
AND (uccm.last_unread_mention_when_emailed_id IS NULL OR uccm.last_unread_mention_when_emailed_id < chat_messages.id)
|
||||
AND users.last_seen_at < now() - interval '15 minutes'
|
||||
AND user_options.chat_enabled
|
||||
AND user_options.chat_email_frequency = #{UserOption.chat_email_frequencies[:when_away]}
|
||||
AND user_options.email_level <> #{UserOption.email_level_types[:never]}
|
||||
AND chat_channels.deleted_at IS NULL
|
||||
AND chat_messages.deleted_at IS NULL
|
||||
AND chat_messages.created_at > now() - interval '1 week'
|
||||
AND chat_messages.user_id <> users.id
|
||||
AND chat_messages.created_by_sdk = false
|
||||
AND (
|
||||
(chat_channels.chatable_type = 'DirectMessage' AND user_options.allow_private_messages) OR
|
||||
(chat_channels.chatable_type = 'Category' AND uccm.following AND NOT notifications.read)
|
||||
WITH eligible_users AS (
|
||||
SELECT DISTINCT u.id, uo.allow_private_messages
|
||||
FROM users u
|
||||
JOIN user_options uo ON uo.user_id = u.id
|
||||
#{groups_join_sql}
|
||||
WHERE u.last_seen_at < now() - interval '15 minutes'
|
||||
AND uo.chat_enabled
|
||||
AND uo.chat_email_frequency = #{UserOption.chat_email_frequencies[:when_away]}
|
||||
AND uo.email_level <> #{UserOption.email_level_types[:never]}
|
||||
), channel_messages AS (
|
||||
SELECT DISTINCT ON (chat_channel_id) chat_channel_id, cm.id AS first_unread_id, user_id AS sender_id
|
||||
FROM chat_messages cm
|
||||
JOIN users sender ON sender.id = cm.user_id
|
||||
WHERE cm.created_at > now() - interval '7 days'
|
||||
AND cm.deleted_at IS NULL
|
||||
AND NOT cm.created_by_sdk
|
||||
ORDER BY chat_channel_id, cm.id
|
||||
)
|
||||
SELECT DISTINCT uccm.user_id
|
||||
FROM user_chat_channel_memberships uccm
|
||||
JOIN chat_channels cc ON cc.id = uccm.chat_channel_id AND cc.deleted_at IS NULL
|
||||
JOIN channel_messages cm ON cm.chat_channel_id = cc.id AND cm.sender_id <> uccm.user_id
|
||||
JOIN eligible_users eu ON eu.id = uccm.user_id
|
||||
LEFT JOIN chat_mentions mn ON mn.chat_message_id = cm.first_unread_id
|
||||
LEFT JOIN chat_mention_notifications cmn ON cmn.chat_mention_id = mn.id
|
||||
LEFT JOIN notifications n ON n.id = cmn.notification_id AND n.user_id = uccm.user_id
|
||||
WHERE NOT uccm.muted
|
||||
AND (uccm.last_read_message_id IS NULL OR cm.first_unread_id > uccm.last_read_message_id)
|
||||
AND (uccm.last_unread_mention_when_emailed_id IS NULL OR cm.first_unread_id > uccm.last_unread_mention_when_emailed_id)
|
||||
AND (
|
||||
(cc.chatable_type = 'DirectMessage' AND eu.allow_private_messages) OR
|
||||
(cc.chatable_type = 'Category' AND uccm.following AND (n.id IS NULL OR NOT n.read))
|
||||
)
|
||||
GROUP BY uccm.user_id
|
||||
SQL
|
||||
end
|
||||
end
|
||||
|
Loading…
Reference in New Issue
Block a user