improve assignment student visibilities group performance
shouldn't join on every group membership belonging to the users (even outside of the course) closes #ADMIN-1112 Change-Id: I87926dfe0e73e9c2b1efc7c2c8b4aae903c02744 Reviewed-on: https://gerrit.instructure.com/153723 Reviewed-by: Jeremy Stanley <jeremy@instructure.com> Reviewed-by: Carl Kibler <ckibler@instructure.com> Tested-by: Jenkins Product-Review: James Williams <jamesw@instructure.com> QA-Review: James Williams <jamesw@instructure.com>
This commit is contained in:
parent
27fa9b1558
commit
585f97765c
|
@ -0,0 +1,120 @@
|
|||
class ImproveAsvGroupPerformance < ActiveRecord::Migration[5.1]
|
||||
tag :postdeploy
|
||||
|
||||
def up
|
||||
# find the groups first and then worry about group memberships
|
||||
self.connection.execute %(CREATE OR REPLACE VIEW #{connection.quote_table_name('assignment_student_visibilities')} AS
|
||||
SELECT DISTINCT a.id as assignment_id,
|
||||
e.user_id as user_id,
|
||||
c.id as course_id
|
||||
|
||||
FROM #{Assignment.quoted_table_name} a
|
||||
|
||||
JOIN #{Course.quoted_table_name} c
|
||||
ON a.context_id = c.id
|
||||
AND a.context_type = 'Course'
|
||||
|
||||
JOIN #{Enrollment.quoted_table_name} e
|
||||
ON e.course_id = c.id
|
||||
AND e.type IN ('StudentEnrollment', 'StudentViewEnrollment')
|
||||
AND e.workflow_state NOT IN ('deleted', 'rejected', 'inactive')
|
||||
|
||||
JOIN #{CourseSection.quoted_table_name} cs
|
||||
ON cs.course_id = c.id
|
||||
AND e.course_section_id = cs.id
|
||||
|
||||
LEFT JOIN #{Group.quoted_table_name} g
|
||||
ON g.context_type = 'Course'
|
||||
AND g.context_id = c.id
|
||||
AND g.workflow_state = 'available'
|
||||
|
||||
LEFT JOIN #{GroupMembership.quoted_table_name} gm
|
||||
ON gm.user_id = e.user_id
|
||||
AND gm.workflow_state = 'accepted'
|
||||
AND gm.group_id = g.id
|
||||
|
||||
LEFT JOIN #{AssignmentOverrideStudent.quoted_table_name} aos
|
||||
ON aos.assignment_id = a.id
|
||||
AND aos.user_id = e.user_id
|
||||
AND aos.workflow_state = 'active'
|
||||
|
||||
LEFT JOIN #{AssignmentOverride.quoted_table_name} ao
|
||||
ON ao.assignment_id = a.id
|
||||
AND ao.workflow_state = 'active'
|
||||
AND (
|
||||
(ao.set_type = 'CourseSection' AND ao.set_id = cs.id)
|
||||
OR (ao.set_type = 'ADHOC' AND ao.set_id IS NULL AND ao.id = aos.assignment_override_id)
|
||||
OR (ao.set_type = 'Group' AND ao.set_id = g.id AND gm.id IS NOT NULL)
|
||||
)
|
||||
|
||||
LEFT JOIN #{Submission.quoted_table_name} s
|
||||
ON s.user_id = e.user_id
|
||||
AND s.assignment_id = a.id
|
||||
AND s.workflow_state NOT IN ('deleted', 'unsubmitted')
|
||||
|
||||
WHERE a.workflow_state NOT IN ('deleted','unpublished')
|
||||
AND(
|
||||
( a.only_visible_to_overrides = 'true' AND (ao.id IS NOT NULL OR s.id IS NOT NULL))
|
||||
OR (COALESCE(a.only_visible_to_overrides, 'false') = 'false')
|
||||
)
|
||||
)
|
||||
end
|
||||
|
||||
def down
|
||||
self.connection.execute %(CREATE OR REPLACE VIEW #{connection.quote_table_name('assignment_student_visibilities')} AS
|
||||
SELECT DISTINCT a.id as assignment_id,
|
||||
e.user_id as user_id,
|
||||
c.id as course_id
|
||||
|
||||
FROM #{Assignment.quoted_table_name} a
|
||||
|
||||
JOIN #{Course.quoted_table_name} c
|
||||
ON a.context_id = c.id
|
||||
AND a.context_type = 'Course'
|
||||
|
||||
JOIN #{Enrollment.quoted_table_name} e
|
||||
ON e.course_id = c.id
|
||||
AND e.type IN ('StudentEnrollment', 'StudentViewEnrollment')
|
||||
AND e.workflow_state NOT IN ('deleted', 'rejected', 'inactive')
|
||||
|
||||
JOIN #{CourseSection.quoted_table_name} cs
|
||||
ON cs.course_id = c.id
|
||||
AND e.course_section_id = cs.id
|
||||
|
||||
LEFT JOIN #{GroupMembership.quoted_table_name} gm
|
||||
ON gm.user_id = e.user_id
|
||||
AND gm.workflow_state = 'accepted'
|
||||
|
||||
LEFT JOIN #{Group.quoted_table_name} g
|
||||
ON g.context_type = 'Course'
|
||||
AND g.context_id = c.id
|
||||
AND g.workflow_state = 'available'
|
||||
AND gm.group_id = g.id
|
||||
|
||||
LEFT JOIN #{AssignmentOverrideStudent.quoted_table_name} aos
|
||||
ON aos.assignment_id = a.id
|
||||
AND aos.user_id = e.user_id
|
||||
AND aos.workflow_state = 'active'
|
||||
|
||||
LEFT JOIN #{AssignmentOverride.quoted_table_name} ao
|
||||
ON ao.assignment_id = a.id
|
||||
AND ao.workflow_state = 'active'
|
||||
AND (
|
||||
(ao.set_type = 'CourseSection' AND ao.set_id = cs.id)
|
||||
OR (ao.set_type = 'ADHOC' AND ao.set_id IS NULL AND ao.id = aos.assignment_override_id)
|
||||
OR (ao.set_type = 'Group' AND ao.set_id = g.id)
|
||||
)
|
||||
|
||||
LEFT JOIN #{Submission.quoted_table_name} s
|
||||
ON s.user_id = e.user_id
|
||||
AND s.assignment_id = a.id
|
||||
AND s.workflow_state NOT IN ('deleted', 'unsubmitted')
|
||||
|
||||
WHERE a.workflow_state NOT IN ('deleted','unpublished')
|
||||
AND(
|
||||
( a.only_visible_to_overrides = 'true' AND (ao.id IS NOT NULL OR s.id IS NOT NULL))
|
||||
OR (COALESCE(a.only_visible_to_overrides, 'false') = 'false')
|
||||
)
|
||||
)
|
||||
end
|
||||
end
|
Loading…
Reference in New Issue