PERF: Speed up `User.assign_allowed` SQL query (#342)

The previous query which uses a subquery in combination with the OR
condition results in the PG planner unable to leverage the indexes we
have available. Instead, the PG planner would loop through each user
record and execute the subquery once per row. As the number of users on
a site increases, this query becomes more and more expensive to run
leading to the query timing out once a certain threshold is reached.

In the new query, we remove the OR condition which allows the PG
planner to the existing indexes more effectively. We also improved the
subquery by removing an unnecessary join against the groups table.
Since `group_users` rows are cleaned up when a group is destroyed so there is
no need for the inner join on the `groups` table.
This commit is contained in:
Alan Guo Xiang Tan 2022-05-30 14:26:20 +08:00 committed by GitHub
parent 959525b079
commit 6d6184d31d
No known key found for this signature in database
GPG Key ID: 4AEE18F83AFDEB23
1 changed files with 14 additions and 4 deletions

View File

@ -155,10 +155,20 @@ after_initialize do
add_class_method(:user, :assign_allowed) do
allowed_groups = SiteSetting.assign_allowed_on_groups.split('|')
where("users.admin OR users.id IN (
SELECT user_id FROM group_users
INNER JOIN groups ON group_users.group_id = groups.id
WHERE groups.id IN (?)
# The UNION against admin users is necessary because bot users like the system user are given the admin status but
# are not added into the admin group.
where("users.id IN (
SELECT
user_id
FROM group_users
WHERE group_users.group_id IN (?)
UNION
SELECT id
FROM users
WHERE users.admin
)", allowed_groups)
end