From 4348b7e213974ce987d58bb96d9a49211c600ae6 Mon Sep 17 00:00:00 2001 From: RomanSteinberg <romanofficial@yandex.com> Date: Tue, 1 Sep 2015 18:42:19 +0300 Subject: [PATCH] ADD: GetRatesForGroupByStage2 to DB --- db/stored/procedures.sql | 68 ++++++++++++++++++++++++++++++++++++++++ 1 file changed, 68 insertions(+) diff --git a/db/stored/procedures.sql b/db/stored/procedures.sql index 3e54ed00d..c1750d6f3 100644 --- a/db/stored/procedures.sql +++ b/db/stored/procedures.sql @@ -1524,5 +1524,73 @@ BEGIN LIMIT 1; END // +# something useful! may be is replaced yet! +DROP PROCEDURE IF EXISTS GetRatesForGroupByStage2// +CREATE PROCEDURE `GetRatesForGroupByStage2` ( + IN `pDisciplineID` INT, + IN `pGroupID` INT, + IN `pMilestone` INT +) NO SQL +BEGIN + DECLARE vSemesterID, vGroupID INT DEFAULT -1; + SET vSemesterID = GetDisciplineProperty(pDisciplineID, 'semester'); + DROP TABLE IF EXISTS tStudents; + CREATE TEMPORARY TABLE tStudents ( + `StudentID` INT NOT NULL + ); + + # check that group attached to discipline. Otherwise vGroupID = -1; + SELECT disciplines_groups.GroupID INTO vGroupID + FROM `disciplines_groups` + WHERE disciplines_groups.GroupID = pGroupID AND + disciplines_groups.DisciplineID = pDisciplineID + LIMIT 1; + + # get all students from group, that take this discipline + IF vGroupID <= 0 THEN # doesn't attached + INSERT INTO tStudents (`StudentID`) + SELECT disciplines_students.StudentID + FROM `disciplines_students` + WHERE disciplines_students.DisciplineID = pDisciplineID AND + disciplines_students.Type = 'attach'; + ELSE # attached group + INSERT INTO tStudents (`StudentID`) + SELECT students_groups.StudentID + FROM `students_groups` + LEFT JOIN `disciplines_students` ON disciplines_students.StudentID = students_groups.StudentID AND + disciplines_students.DisciplineID = pDisciplineID + WHERE students_groups.GroupID = vGroupID AND + students_groups.SemesterID = vSemesterID AND + NOT disciplines_students.Type <=> 'detach'; # exclude detached students + END IF; + + SELECT tRes.*, + students.LastName, + students.FirstName, + students.SecondName + FROM ( + SELECT tStudents.StudentID, + SUM(tRate.Rate*(tMap.ModuleType = 'regular')) AS 'Semester', + SUM(tRate.Rate*(tMap.ModuleType = 'bonus')) AS 'Bonus', + SUM(tRate.Rate*(tMap.ModuleType = 'extra')*(tMap.SubmoduleOrderNum < pMilestone)) AS 'Extra', + SUM(tRate.Rate*(tMap.ModuleType = 'extra')*(tMap.SubmoduleOrderNum < pMilestone - 1)) AS 'PreviousExtra', + SUM(tRate.Rate*(tMap.ModuleType = 'exam')*(tMap.SubmoduleOrderNum = pMilestone)) AS 'Exam', + MAX(tRate.Rate*(tMap.ModuleType = 'exam')*(tMap.SubmoduleOrderNum < pMilestone)) AS 'PreviousExam', + MAX(tRate.Rate*(tMap.ModuleType = 'exam')*(tMap.SubmoduleOrderNum < pMilestone - 1)) AS 'PrePreviousExam', + MAX(IF(tMap.SubmoduleOrderNum = pMilestone, exam_period_options.TYPE, NULL)) As 'Option', + MAX(IF(exam_period_options.TYPE = 'pass', 1, 0)) As 'AutoPassed' + FROM `tStudents` + LEFT JOIN `view_roadmap` AS tMap ON tMap.DisciplineID = pDisciplineID + LEFT JOIN `rating_table` AS tRate ON tRate.StudentID = tStudents.StudentID AND + tRate.SubmoduleID = tMap.SubmoduleID + LEFT JOIN `exam_period_options` ON exam_period_options.submoduleID = tMap.SubmoduleID AND + exam_period_options.StudentID = tStudents.StudentID + GROUP BY tStudents.StudentID + ) tRes + INNER JOIN `students` ON students.ID = tRes.StudentID + ORDER BY students.LastName ASC, + students.FirstName ASC, + students.SecondName ASC; +END // DELIMITER ; -- GitLab