PERF: Avoid `NOT IN (<subquery>>` which can get really slow.
``` EXPLAIN ANALYZE SELECT "topics".* FROM "topics" LEFT JOIN topic_users tu ON topics.id = tu.topic_id AND tu.user_id = 13455 WHERE ("topics"."deleted_at" IS NULL) AND (topics.archetype = 'private_message') AND ( topics.id IN ( SELECT topic_id FROM topic_allowed_users WHERE user_id = 13455 ) ) AND ( topics.id IN ( SELECT ta.topic_id FROM topic_allowed_users ta WHERE ta.user_id IN (2,1995,8307,17621,22980,-10) ) OR topics.id IN ( SELECT tg.topic_id FROM topic_allowed_groups tg WHERE tg.group_id IN (-10) ) ) AND (topics.id NOT IN (68559,60069,42145)) AND "topics"."visible" = 't' ORDER BY topics.bumped_at DESC LIMIT 5; ``` Planning time: 1.196 ms Execution time: 21.176 ms ``` EXPLAIN ANALYZE SELECT "topics".* FROM "topics" LEFT JOIN topic_users tu ON topics.id = tu.topic_id AND tu.user_id = 13455 LEFT JOIN topic_allowed_users ta ON topics.id = ta.topic_id AND ta.user_id = 13455 LEFT JOIN topic_allowed_users ta2 ON topics.id = ta2.topic_id AND ta2.user_id IN (2,1995,8307,17621,22980,-10) LEFT JOIN topic_allowed_groups tg ON topics.id = tg.topic_id AND tg.group_id IN (-10) WHERE ("topics"."deleted_at" IS NULL) AND (topics.archetype = 'private_message') AND (ta.topic_id IS NOT NULL) AND (ta2.topic_id IS NOT NULL OR tg.topic_id IS NOT NULL) AND (topics.id NOT IN (68559,60069,42145)) AND "topics"."visible" = 't' ORDER BY topics.bumped_at DESC LIMIT 5; ``` Planning time: 1.792 ms Execution time: 2.546 ms
This commit is contained in:
parent
b537bf1ba4
commit
28148197d6
|
@ -107,8 +107,13 @@ class TopicQuery
|
|||
if topic.private_message?
|
||||
|
||||
group_ids = topic.topic_allowed_groups
|
||||
.where('group_id IN (SELECT group_id FROM group_users WHERE user_id = :user_id)', user_id: @user.id)
|
||||
.joins("
|
||||
LEFT JOIN group_users gu
|
||||
ON topic_allowed_groups.group_id = gu.group_id
|
||||
AND user_id = #{@user.id.to_i}
|
||||
")
|
||||
.pluck(:group_id)
|
||||
|
||||
{
|
||||
topic: topic,
|
||||
my_group_ids: group_ids,
|
||||
|
@ -743,21 +748,24 @@ class TopicQuery
|
|||
end
|
||||
|
||||
def related_messages_user(params)
|
||||
messages_for_user
|
||||
.limit(params[:count])
|
||||
.where('topics.id IN (
|
||||
SELECT ta.topic_id
|
||||
FROM topic_allowed_users ta
|
||||
WHERE ta.user_id IN (:user_ids)
|
||||
) OR
|
||||
topics.id IN (
|
||||
SELECT tg.topic_id
|
||||
FROM topic_allowed_groups tg
|
||||
WHERE tg.group_id IN (:group_ids)
|
||||
)
|
||||
', user_ids: (params[:target_user_ids] || []) + [-10],
|
||||
group_ids: ((params[:target_group_ids] - params[:my_group_ids]) || []) + [-10])
|
||||
user_ids = ((params[:target_user_ids] || []) << -10)
|
||||
user_ids = ActiveRecord::Base.send(:sanitize_sql_array, user_ids.join(','))
|
||||
group_ids = (((params[:target_group_ids] - params[:my_group_ids]) || []) << -10)
|
||||
group_ids = ActiveRecord::Base.send(:sanitize_sql_array, group_ids.join(','))
|
||||
|
||||
result = messages_for_user
|
||||
.limit(params[:count])
|
||||
.joins("
|
||||
LEFT JOIN topic_allowed_users ta2
|
||||
ON topics.id = ta2.topic_id
|
||||
AND ta2.user_id IN (#{user_ids})",
|
||||
)
|
||||
.joins("
|
||||
LEFT JOIN topic_allowed_groups tg
|
||||
ON topics.id = tg.topic_id
|
||||
AND tg.group_id IN (#{group_ids})",
|
||||
)
|
||||
.where("ta2.topic_id IS NOT NULL OR tg.topic_id IS NOT NULL")
|
||||
end
|
||||
|
||||
def related_messages_group(params)
|
||||
|
@ -793,11 +801,13 @@ class TopicQuery
|
|||
end
|
||||
|
||||
def messages_for_user
|
||||
base_messages.where('topics.id IN (
|
||||
SELECT topic_id
|
||||
FROM topic_allowed_users
|
||||
WHERE user_id = :user_id
|
||||
)', user_id: @user.id)
|
||||
base_messages
|
||||
.joins("
|
||||
LEFT JOIN topic_allowed_users ta
|
||||
ON topics.id = ta.topic_id
|
||||
AND ta.user_id = #{@user.id.to_i}
|
||||
")
|
||||
.where("ta.topic_id IS NOT NULL")
|
||||
end
|
||||
|
||||
def base_messages
|
||||
|
|
Loading…
Reference in New Issue