From d6765bd7d6b0225d4308716c551b98f85a443b75 Mon Sep 17 00:00:00 2001 From: =?UTF-8?q?Santeri=20Rajam=C3=A4ki?= Date: Mon, 27 Jan 2025 16:19:55 +0200 Subject: [PATCH] [Class statistics] Improved performance of "Courses of Class" tab Closes #4715 --- .../src/services/populations/bottlenecksOf.ts | 57 +++++---- .../src/services/populations/shared.ts | 108 +++++++++--------- 2 files changed, 79 insertions(+), 86 deletions(-) diff --git a/services/backend/src/services/populations/bottlenecksOf.ts b/services/backend/src/services/populations/bottlenecksOf.ts index 3393cacb0f..5a813b54e3 100644 --- a/services/backend/src/services/populations/bottlenecksOf.ts +++ b/services/backend/src/services/populations/bottlenecksOf.ts @@ -22,39 +22,34 @@ const getStudentsAndCourses = async ( studentNumbers: string[] | null, courseCodes: string[] | undefined ): Promise<[number, CoursesQueryResult, EnrollmentsQueryResult]> => { - if (!studentNumbers) { - const { months, studyRights, startDate, endDate, exchangeStudents, nondegreeStudents, transferredStudents } = params - const studentnumbers = - selectedStudents ?? - (await getStudentNumbersWithAllStudyRightElements({ - studyRights, - startDate, - endDate, - exchangeStudents, - nondegreeStudents, - transferredOutStudents: transferredStudents, - })) - - const allStudents = studentnumbers.length - const courses = await findCourses(studentnumbers, dateMonthsFromNow(startDate, months), courseCodes) - const foundCourseCodes = Object.keys(keyBy(courses, 'code')) - const filteredCourseCodes = courseCodes?.filter(code => !foundCourseCodes.includes(code)) - const courseEnrollments = await findCourseEnrollments( - studentnumbers, - dateMonthsFromNow(startDate, months), - filteredCourseCodes - ) - - return [allStudents, courses, courseEnrollments] - } + const { months, studyRights, startDate, endDate, exchangeStudents, nondegreeStudents, transferredStudents } = params + + const studentnumbers = + studentNumbers ?? + selectedStudents ?? + (await getStudentNumbersWithAllStudyRightElements({ + studyRights, + startDate, + endDate, + exchangeStudents, + nondegreeStudents, + transferredOutStudents: transferredStudents, + })) + + const allStudents = studentnumbers.length - const { months, startDate } = params const beforeDate = months && startDate ? dateMonthsFromNow(startDate, months) : new Date() - const allStudents = studentNumbers.length - const courses = await findCourses(studentNumbers, beforeDate, courseCodes) - const foundCourseCodes = Object.keys(keyBy(courses, 'code')) + const courses = !studentNumbers + ? await findCourses(studentnumbers, dateMonthsFromNow(startDate, months), courseCodes) + : await findCourses(studentnumbers, beforeDate, courseCodes) + + const foundCourseCodes = [...new Set(courses.map(({ code }) => code))].toSorted() const filteredCourseCodes = courseCodes?.filter(code => !foundCourseCodes.includes(code)) - const courseEnrollments = await findCourseEnrollments(studentNumbers, beforeDate, filteredCourseCodes) + const courseEnrollments = filteredCourseCodes?.length + ? !studentNumbers + ? await findCourseEnrollments(studentnumbers, dateMonthsFromNow(startDate, months), filteredCourseCodes) + : await findCourseEnrollments(studentnumbers, beforeDate, filteredCourseCodes) + : [] return [allStudents, courses, courseEnrollments] } @@ -149,7 +144,7 @@ export const bottlenecksOf = async (query: Query, studentNumbers: string[] | nul }) } if ('credits' in course) { - course.credits.forEach(credit => { + course.credits?.forEach(credit => { const { studentnumber, passingGrade, improvedGrade, failingGrade, grade, date } = parseCreditInfo(credit) if (query?.selectedStudents?.includes(studentnumber) || !query?.selectedStudents) { const semester = getPassingSemester(startYear, date) diff --git a/services/backend/src/services/populations/shared.ts b/services/backend/src/services/populations/shared.ts index f43e6a4d23..2c919e37d6 100644 --- a/services/backend/src/services/populations/shared.ts +++ b/services/backend/src/services/populations/shared.ts @@ -448,24 +448,6 @@ export const formatStudentsForApi = ( } } -const getSubstitutions = async (codes: string[]) => { - const courses = await Course.findAll({ - attributes: ['code', 'substitutions'], - where: { - code: { - [Op.iLike]: { [Op.any]: codes }, - }, - }, - raw: true, - }) - - const substitutions = [ - ...new Set(courses.flatMap(({ code, substitutions }) => [code, ...Object.values(substitutions).flat()])), - ] - - return substitutions -} - export type EnrollmentsQueryResult = Array<{ code: string name: Name @@ -482,12 +464,10 @@ export type CoursesQueryResult = Array< } > -// This duplicate code is added here to ensure that we get the enrollments in cases no credits found for the selected students export const findCourseEnrollments = async (studentNumbers: string[], beforeDate: Date, courses: string[] = []) => { - const courseCodes = courses.length === 0 ? ['DUMMY'] : await getSubstitutions(courses) const result: EnrollmentsQueryResult = await sequelize.query( ` - SELECT DISTINCT ON (course.id) + SELECT DISTINCT course.code, course.name, course.substitutions, @@ -496,24 +476,32 @@ export const findCourseEnrollments = async (studentNumbers: string[], beforeDate FROM course INNER JOIN ( SELECT - course_id, - ARRAY_AGG(JSON_BUILD_OBJECT( + course_code, + ARRAY_AGG(JSONB_BUILD_OBJECT( 'studentnumber', studentnumber, 'state', state, 'enrollment_date_time', enrollment_date_time )) AS data FROM enrollment - WHERE enrollment.studentnumber IN (:studentnumbers) AND enrollment.enrollment_date_time < :beforeDate AND enrollment.state = :enrollmentState - GROUP BY enrollment.course_id - ) enrollment ON enrollment.course_id = course.id - WHERE :skipCourseCodeFilter OR course.code IN (:courseCodes) + WHERE studentnumber IN (:studentnumbers) + AND enrollment_date_time < :beforeDate + AND state = :enrollmentState + GROUP BY course_code + ) AS enrollment + ON enrollment.course_code = course.code + WHERE course.code IN (:courseCodes) + OR ( + SELECT + JSONB_AGG(DISTINCT alt_code) + FROM course, LATERAL JSONB_ARRAY_ELEMENTS(substitutions) as alt_code + WHERE code IN (:courseCodes) + ) ? course.code `, { replacements: { studentnumbers: studentNumbers.length > 0 ? studentNumbers : ['DUMMY'], beforeDate, - courseCodes, - skipCourseCodeFilter: courses.length === 0, + courseCodes: courses.length ? courses : ['DUMMY'], enrollmentState: EnrollmentState.ENROLLED, }, type: QueryTypes.SELECT, @@ -523,21 +511,35 @@ export const findCourseEnrollments = async (studentNumbers: string[], beforeDate } export const findCourses = async (studentNumbers: string[], beforeDate: Date, courses: string[] = []) => { - const courseCodes = courses.length === 0 ? ['DUMMY'] : await getSubstitutions(courses) - const result: CoursesQueryResult = await sequelize.query( + return sequelize.query( ` - SELECT DISTINCT ON (course.id) + SELECT course.code, course.name, course.substitutions, course.main_course_code, - credit.data AS credits, - enrollment.data AS enrollments + enrollment.data AS enrollments, + credit.data AS credits FROM course - INNER JOIN ( + LEFT JOIN ( + SELECT + course_code, + ARRAY_AGG(JSONB_BUILD_OBJECT( + 'studentnumber', studentnumber, + 'state', state, + 'enrollment_date_time', enrollment_date_time + )) AS data + FROM enrollment + WHERE studentnumber IN (:studentnumbers) + AND enrollment_date_time < :beforeDate + AND state = :enrollmentState + GROUP BY course_code + ) AS enrollment + ON enrollment.course_code = course.code + LEFT JOIN ( SELECT course_code, - ARRAY_AGG(JSON_BUILD_OBJECT( + ARRAY_AGG(JSONB_BUILD_OBJECT( 'grade', grade, 'student_studentnumber', student_studentnumber, 'attainment_date', attainment_date, @@ -545,35 +547,31 @@ export const findCourses = async (studentNumbers: string[], beforeDate: Date, co 'course_code', course_code )) AS data FROM credit - WHERE student_studentnumber IN (:studentnumbers) AND attainment_date < :beforeDate - GROUP BY credit.course_code - ) credit ON credit.course_code = course.code - LEFT JOIN ( - SELECT - course_id, - ARRAY_AGG(JSON_BUILD_OBJECT( - 'studentnumber', studentnumber, - 'state', state, - 'enrollment_date_time', enrollment_date_time - )) AS data - FROM enrollment - WHERE enrollment.studentnumber IN (:studentnumbers) AND enrollment.enrollment_date_time < :beforeDate AND enrollment.state = :enrollmentState - GROUP BY enrollment.course_id - ) enrollment ON enrollment.course_id = course.id - WHERE :skipCourseCodeFilter OR course.code IN (:courseCodes) + WHERE student_studentnumber IN (:studentnumbers) + AND attainment_date < :beforeDate + GROUP BY course_code + ) AS credit + ON credit.course_code = course.code + WHERE :skipCourseCodeFilter + OR course.code IN (:courseCodes) + OR ( + SELECT + JSONB_AGG(DISTINCT alt_code) + FROM course, LATERAL JSONB_ARRAY_ELEMENTS(substitutions) as alt_code + WHERE code IN (:courseCodes) + ) ? course.code `, { replacements: { studentnumbers: studentNumbers.length > 0 ? studentNumbers : ['DUMMY'], beforeDate, - courseCodes, + courseCodes: courses.length ? courses : ['DUMMY'], skipCourseCodeFilter: courses.length === 0, enrollmentState: EnrollmentState.ENROLLED, }, type: QueryTypes.SELECT, } - ) - return result + ) as Promise } export const parseCreditInfo = (credit: CreditPick) => {