Use DISTINCT ON and translate to MySQL.

Realized window functions are not available in older MySQL versions
either.

Falling back to DISTINCT ON for postgresql and a convoluted translation
for MySQL.
This commit is contained in:
Andreas Brandl 2018-02-19 18:28:11 +01:00
parent df7d65a7aa
commit c2ae4a6399
1 changed files with 34 additions and 16 deletions

View File

@ -17,22 +17,7 @@ class MembersFinder
union = Gitlab::SQL::Union.new([project_members, group_members], remove_duplicates: false)
# We're interested in a list of members without duplicates by user_id.
# We prefer project members over group members, project members should go first.
#
# We could have used a DISTINCT ON here, but MySQL does not support this.
sql = <<-SQL
SELECT member_numbered.*
FROM (
SELECT
member_union.*,
ROW_NUMBER() OVER (
PARTITION BY user_id ORDER BY CASE WHEN type = 'ProjectMember' THEN 1 WHEN type = 'GroupMember' THEN 2 ELSE 3 END
) AS row_number
FROM (#{union.to_sql}) AS member_union
) AS member_numbered
WHERE row_number = 1
SQL
sql = distinct_on(union)
Member.from("(#{sql}) AS #{Member.table_name}")
else
@ -43,4 +28,37 @@ class MembersFinder
def can?(*args)
Ability.allowed?(*args)
end
private
def distinct_on(union)
# We're interested in a list of members without duplicates by user_id.
# We prefer project members over group members, project members should go first.
if Gitlab::Database.postgresql?
<<~SQL
SELECT DISTINCT ON (user_id, invite_email) member_union.*
FROM (#{union.to_sql}) AS member_union
ORDER BY
user_id, invite_email,
CASE WHEN type = 'ProjectMember' THEN 1 WHEN type = 'GroupMember' THEN 2 ELSE 3 END
SQL
else
# Older versions of MySQL do not support window functions (and DISTINCT ON is postgres-specific).
<<~SQL
SELECT t1.*
FROM (#{union.to_sql}) AS t1
JOIN (
SELECT
COALESCE(user_id, -1) AS user_id,
COALESCE(invite_email, 'NULL') AS invite_email,
MIN(CASE WHEN type = 'ProjectMember' THEN 1 WHEN type = 'GroupMember' THEN 2 ELSE 3 END) AS type_number
FROM
(#{union.to_sql}) AS t3
GROUP BY COALESCE(user_id, -1), COALESCE(invite_email, 'NULL')
) AS t2 ON COALESCE(t1.user_id, -1) = t2.user_id
AND COALESCE(t1.invite_email, 'NULL') = t2.invite_email
AND CASE WHEN t1.type = 'ProjectMember' THEN 1 WHEN t1.type = 'GroupMember' THEN 2 ELSE 3 END = t2.type_number
SQL
end
end
end