From 889f392cd61d4b23a1b780212544f009bd2e5539 Mon Sep 17 00:00:00 2001 From: PavelBegunkov <asml.silence@gmail.com> Date: Tue, 8 Sep 2015 22:15:35 +0300 Subject: [PATCH] Improvements - Complex report optimization - Max rate calculation optimization --- db/fixes/15_09_13.sql | 18 +++ db/stored/functions.sql | 29 ++-- db/stored/procedures.sql | 12 +- db/stored/triggers.sql | 147 ++++++++++++++++++ db/stored/views.sql | 14 +- db/structure/base.sql | 4 + media/less/teacher/rating.less | 1 + .../classes/Controller/Handler/Map.php | 3 +- .../application/views/student/subject.twig | 6 +- 9 files changed, 195 insertions(+), 39 deletions(-) create mode 100644 db/fixes/15_09_13.sql create mode 100644 db/stored/triggers.sql diff --git a/db/fixes/15_09_13.sql b/db/fixes/15_09_13.sql new file mode 100644 index 000000000..f4bc02770 --- /dev/null +++ b/db/fixes/15_09_13.sql @@ -0,0 +1,18 @@ +alter table disciplines add column `MaxRate` INT(11) NOT NULL DEFAULT 0, + add column `CurRate` INT(11) NOT NULL DEFAULT 0; + +update disciplines +set MaxRate = 1; + +update disciplines +set MaxRate = COALESCE(( + select view_disciplines_results.DisciplineRateMax + from view_disciplines_results + where view_disciplines_results.DisciplineID = disciplines.ID +), 0), +CurRate = COALESCE(( + select view_disciplines_results.DisciplineRateCur + from view_disciplines_results + where view_disciplines_results.DisciplineID = disciplines.ID +), 0); + diff --git a/db/stored/functions.sql b/db/stored/functions.sql index f16126f29..5e3f60196 100644 --- a/db/stored/functions.sql +++ b/db/stored/functions.sql @@ -183,9 +183,9 @@ NO SQL BEGIN DECLARE vMaxRate INT DEFAULT -1; - SELECT view_disciplines_results.DisciplineRateMax INTO vMaxRate - FROM `view_disciplines_results` - WHERE view_disciplines_results.DisciplineID = pDisciplineID + SELECT disciplines.MaxRate INTO vMaxRate + FROM disciplines + WHERE disciplines.ID = pDisciplineID LIMIT 1; RETURN ( vMaxRate = 100 ); END // @@ -997,10 +997,7 @@ BEGIN # TODO: extract method addExtraModule IF pExamType = 'exam' THEN # change to exam # count discipline's current max rate - SELECT view_disciplines_results.DisciplineRateMax INTO vChecker - FROM `view_disciplines_results` - WHERE view_disciplines_results.DisciplineID = pDisciplineID - LIMIT 1; + SET vChecker = InternalIsMapCreated(pDisciplineID); IF vChecker >= 61 THEN # can't add exam module ( > 100 points) RETURN 1; END IF; @@ -1345,14 +1342,14 @@ BEGIN # clear logs DELETE FROM `logs_rating` - WHERE logs_rating.SubModuleID IN + WHERE logs_rating.SubmoduleID IN (SELECT view_roadmap.SubmoduleID FROM `view_roadmap` WHERE view_roadmap.DisciplineID = pDisciplineID); # clear rating DELETE FROM `rating_table` - WHERE rating_table.SubModuleID IN + WHERE rating_table.SubmoduleID IN (SELECT view_roadmap.SubmoduleID FROM `view_roadmap` WHERE view_roadmap.DisciplineID = pDisciplineID); @@ -1794,6 +1791,7 @@ BEGIN END IF; # get bonus module ID + -- todo: extract method SELECT modules.ID INTO vBonusModuleID FROM `modules` WHERE modules.Type = 'bonus' AND @@ -1833,12 +1831,11 @@ BEGIN # check that discipline and submodule exists and doesn't locked SELECT disciplines.IsLocked, - view_disciplines_results.DisciplineRateMax - submodules.MaxRate + pMaxRate + disciplines.MaxRate - submodules.MaxRate + pMaxRate INTO vIsLocked, vNewDiscMaxRate FROM `submodules` INNER JOIN `modules` ON submodules.ModuleID = modules.ID INNER JOIN `disciplines` ON disciplines.ID = modules.DisciplineID - INNER JOIN `view_disciplines_results` ON view_disciplines_results.DisciplineID = disciplines.ID WHERE submodules.ID = pSubmoduleID AND disciplines.AuthorID = pTeacherID LIMIT 1; @@ -2116,7 +2113,7 @@ BEGIN IF pRate < 0 THEN INSERT INTO `logs_rating` (StudentID, SubmoduleID, TeacherID, Rate, Action ) - VALUES (pStudentID, pSubModuleID, pTeacherID, pRate, 'delete'); + VALUES (pStudentID, pSubmoduleID, pTeacherID, pRate, 'delete'); # TODO: extract method log rate DELETE FROM `rating_table` @@ -2139,7 +2136,7 @@ BEGIN FROM `submodules` INNER JOIN `modules` ON submodules.ModuleID = modules.ID INNER JOIN `disciplines` ON modules.DisciplineID = disciplines.ID - WHERE submodules.ID = pSubModuleID + WHERE submodules.ID = pSubmoduleID LIMIT 1; # correct max rate for extra module @@ -2171,7 +2168,7 @@ BEGIN # log rate INSERT INTO `logs_rating` (StudentID, SubmoduleID, TeacherID, Rate, Action ) - VALUES (pStudentID, pSubModuleID, pTeacherID, pRate, + VALUES (pStudentID, pSubmoduleID, pTeacherID, pRate, CASE WHEN @tmp > 0 THEN 'add' ELSE 'change' END); # lock discipline for structure editing @@ -2186,7 +2183,7 @@ BEGIN IF NOT vIsUsed THEN UPDATE `submodules` SET submodules.IsUsed = TRUE - WHERE submodules.ID = pSubModuleID + WHERE submodules.ID = pSubmoduleID LIMIT 1; END IF; RETURN 0; @@ -2305,7 +2302,7 @@ BEGIN LIMIT 1; IF vChecker <= 0 THEN - RETURN ''; + RETURN ''; END IF; END IF; diff --git a/db/stored/procedures.sql b/db/stored/procedures.sql index 449530ec0..a3cb35e2c 100644 --- a/db/stored/procedures.sql +++ b/db/stored/procedures.sql @@ -802,9 +802,8 @@ BEGIN view_disciplines.SubjectID, view_disciplines.SubjectName, view_disciplines.ExamType AS 'Type', - (view_disciplines_results.DisciplineRateMax = 100) AS 'isMapCreated' + (view_disciplines.MaxRate = 100) AS 'isMapCreated' FROM `view_disciplines` - INNER JOIN `view_disciplines_results` ON view_disciplines_results.DisciplineID = view_disciplines.DisciplineID WHERE view_disciplines.SemesterID = pSemesterID AND view_disciplines.FacultyID = pFacultyID ORDER BY view_disciplines.SubjectName ASC; @@ -844,12 +843,11 @@ BEGIN view_disciplines.SubjectName, view_disciplines.AuthorID, view_disciplines.IsLocked AS 'IsLocked', # TODO: change column name - (view_disciplines_results.DisciplineRateMax = 100) AS 'IsMapCreated' + (view_disciplines.MaxRate = 100) AS 'IsMapCreated' FROM `disciplines_teachers` LEFT JOIN `disciplines_groups` ON disciplines_groups.DisciplineID = disciplines_teachers.DisciplineID LEFT JOIN `view_groups` ON view_groups.GroupID = disciplines_groups.GroupID LEFT JOIN `view_disciplines` ON disciplines_teachers.DisciplineID = view_disciplines.DisciplineID - LEFT JOIN `view_disciplines_results` ON view_disciplines_results.DisciplineID = view_disciplines.DisciplineID WHERE disciplines_teachers.TeacherID = pTeacherID AND view_disciplines.SemesterID = pSemesterID ORDER BY view_disciplines.GradeID ASC, @@ -969,16 +967,14 @@ BEGIN view_disciplines.ExamType AS 'Type', view_disciplines.CompoundDiscID, view_disciplines.CompoundDiscName, - view_disciplines_results.DisciplineRateCur as 'CurRate', - view_disciplines_results.DisciplineRateMax as 'MaxRate' + view_disciplines.CurRate, + view_disciplines.MaxRate FROM tDisc INNER JOIN `view_disciplines` ON tDisc.DisciplineID = view_disciplines.DisciplineID - LEFT JOIN `view_disciplines_results` ON tDisc.DisciplineID = view_disciplines_results.DisciplineID WHERE view_disciplines.SemesterID = pSemesterID; END // - # ------------------------------------------------------------------------------------------- # Label: rating # ------------------------------------------------------------------------------------------- diff --git a/db/stored/triggers.sql b/db/stored/triggers.sql new file mode 100644 index 000000000..244acec3a --- /dev/null +++ b/db/stored/triggers.sql @@ -0,0 +1,147 @@ +SET SQL_MODE = "NO_AUTO_VALUE_ON_ZERO"; +SET time_zone = "+00:00"; + + +/*!40101 SET @OLD_CHARACTER_SET_CLIENT=@@CHARACTER_SET_CLIENT */; +/*!40101 SET @OLD_CHARACTER_SET_RESULTS=@@CHARACTER_SET_RESULTS */; +/*!40101 SET @OLD_COLLATION_CONNECTION=@@COLLATION_CONNECTION */; +/*!40101 SET NAMES utf8 */; + +SET SQL_MODE = "NO_AUTO_VALUE_ON_ZERO"; +SET time_zone = "+00:00"; + + +delimiter // + +-- tr - abbr trigger +-- i - insert +-- u - update +-- d - delete + + +drop trigger if exists tr_i_submodule// +create trigger tr_i_submodule + before insert on submodules for each row +begin + declare vDisciplineID int default 0; + declare vAccumType, vChangeMax boolean default false; + declare vModuleType enum('regular','exam', 'bonus', 'extra') default 'extra'; + + -- todo: check repeated bonus + select modules.Type into vModuleType + from modules + where modules.ID = new.ModuleID + limit 1; + + -- todo: in operator + if (vModuleType <=> 'regular' or vModuleType <=> 'exam') then begin + set vAccumType = (not vModuleType <=> 'exam'); + + -- todo: extract foo + set vDisciplineID = ( + select disciplines.ID + from modules + inner join disciplines on disciplines.ID = modules.DisciplineID + where modules.ID = new.ModuleID + limit 1 + ); + + set vChangeMax = vAccumType || new.OrderNum <=> 1; + + update disciplines + set disciplines.CurRate = disciplines.CurRate + if(new.isUsed, new.MaxRate, 0), + disciplines.MaxRate = disciplines.MaxRate + if(vChangeMax, new.MaxRate, 0) + where disciplines.ID = vDisciplineID + limit 1; + end; end if; +end// + +drop trigger if exists tr_d_submodule// +create trigger tr_d_submodule + before delete on submodules for each row +begin + declare vDisciplineID int default 0; + declare vAccumType, vChangeMax boolean default false; + declare vModuleType enum('regular','exam', 'bonus', 'extra') default 'extra'; + + -- todo: check repeated bonus + select modules.Type into vModuleType + from modules + where modules.ID = old.ModuleID + limit 1; + + + if (vModuleType <=> 'regular' or vModuleType <=> 'exam') then begin + set vAccumType = (not vModuleType <=> 'exam'); + + -- todo: extract foo + set vDisciplineID = ( + select disciplines.ID + from modules + inner join disciplines on disciplines.ID = modules.DisciplineID + where modules.ID = old.ModuleID + limit 1 + ); + + set vChangeMax = vAccumType || old.OrderNum <=> 1; + + update disciplines + set disciplines.CurRate = disciplines.CurRate - if(old.isUsed, old.MaxRate, 0), + disciplines.MaxRate = disciplines.MaxRate - if(vChangeMax, old.MaxRate, 0) + where disciplines.ID = vDisciplineID + limit 1; + end; end if; + +end// + +drop trigger if exists tr_u_submodule// +create trigger tr_u_submodule + before update on submodules for each row +begin + declare vDisciplineID int default 0; + declare vAccumType, vChangeMaxOld, vChangeMaxNew boolean default false; + declare vModuleType enum('regular','exam', 'bonus', 'extra') default 'extra'; + + if old.ModuleID != new.ModuleID then + signal sqlstate '45000'; + end if; + + -- todo: check repeated bonus + select modules.Type into vModuleType + from modules + where modules.ID = new.ModuleID + limit 1; + + + if (vModuleType <=> 'regular' or vModuleType <=> 'exam') then begin + set vAccumType = (not vModuleType <=> 'exam'); + + -- todo: extract foo + set vDisciplineID = ( + select disciplines.ID + from modules + inner join disciplines on disciplines.ID = modules.DisciplineID + where modules.ID = old.ModuleID + limit 1 + ); + + set vChangeMaxOld = vAccumType || old.OrderNum <=> 1; + set vChangeMaxNew = vAccumType || new.OrderNum <=> 1; + + update disciplines + set disciplines.CurRate = disciplines.CurRate + - if(old.isUsed, old.MaxRate, 0) + + if(new.isUsed, new.MaxRate, 0), + disciplines.MaxRate = disciplines.MaxRate + - if(vChangeMaxOld, old.MaxRate, 0) + + if(vChangeMaxNew, new.MaxRate, 0) + where disciplines.ID = vDisciplineID + limit 1; + end; end if; + +end// + + +delimiter ; + + diff --git a/db/stored/views.sql b/db/stored/views.sql index 967a6a00d..30de062ca 100644 --- a/db/stored/views.sql +++ b/db/stored/views.sql @@ -10,6 +10,7 @@ SET time_zone = "+00:00"; DROP VIEW IF EXISTS view_disciplines_teachers; DROP VIEW IF EXISTS `view_disciplines_students`; DROP VIEW IF EXISTS `view_rating_result`; +DROP VIEW IF EXISTS view_disciplines_results; @@ -77,6 +78,8 @@ CREATE OR REPLACE VIEW `view_disciplines` AS disciplines.Milestone, disciplines.Subtype, disciplines.CompoundDiscID, + disciplines.MaxRate, + disciplines.CurRate, grades.ID AS 'GradeID', grades.Num AS 'GradeNum', grades.Degree, @@ -111,14 +114,3 @@ CREATE OR REPLACE VIEW `view_roadmap` AS FROM `modules` LEFT JOIN `submodules` ON submodules.ModuleID = modules.ID; - -CREATE OR REPLACE VIEW `view_disciplines_results` AS - SELECT disciplines.ID AS 'DisciplineID', - SUM(submodules.MaxRate) AS 'DisciplineRateMax', - SUM(submodules.MaxRate*submodules.IsUsed) AS 'DisciplineRateCur' - FROM `disciplines` - LEFT JOIN `modules` ON modules.DisciplineID = disciplines.ID - LEFT JOIN `submodules` ON submodules.ModuleID = modules.ID - WHERE modules.Type = 'regular' OR - (modules.Type = 'exam' AND submodules.OrderNum = 1) - GROUP BY disciplines.ID; diff --git a/db/structure/base.sql b/db/structure/base.sql index 04ab6480f..d5e2bb12c 100644 --- a/db/structure/base.sql +++ b/db/structure/base.sql @@ -104,6 +104,10 @@ CREATE TABLE IF NOT EXISTS `disciplines` ( `MilestoneDate` DATE NULL DEFAULT NULL, `Subtype` enum('scientific_coursework', 'disciplinary_coursework' ) NULL DEFAULT NULL, `CompoundDiscID` INT(11) NULL DEFAULT NULL, + + `MaxRate` INT(11) NOT NULL DEFAULT 0, + `CurRate` INT(11) NOT NULL DEFAULT 0, + PRIMARY KEY (`ID`), KEY `GradeID` (`GradeID`), KEY `SubjectID` (`SubjectID`), diff --git a/media/less/teacher/rating.less b/media/less/teacher/rating.less index cb82fb0fb..998254965 100644 --- a/media/less/teacher/rating.less +++ b/media/less/teacher/rating.less @@ -80,6 +80,7 @@ td.rateResultCell { .groupSelector { display: inline-block; + margin-left: 5px; padding: 5px; border: 1px solid #d7d7d7; background: #ffffff; diff --git a/~dev_rating/application/classes/Controller/Handler/Map.php b/~dev_rating/application/classes/Controller/Handler/Map.php index 0ee897227..415d9c2a0 100644 --- a/~dev_rating/application/classes/Controller/Handler/Map.php +++ b/~dev_rating/application/classes/Controller/Handler/Map.php @@ -27,7 +27,8 @@ class Controller_Handler_Map extends Controller_Handler $discipline = Model_Discipline::load($_POST['DisciplineID']); $map = Model_Map::of($discipline); - if ($this->post['BonusRate'] == true) { + + if ($this->post['BonusRate'] === "true") { $failed = $map->AddModuleBonus($this->user->TeacherID); $response['action'] = 'add'; } else { diff --git a/~dev_rating/application/views/student/subject.twig b/~dev_rating/application/views/student/subject.twig index 46bf779cd..2b50c6a2e 100644 --- a/~dev_rating/application/views/student/subject.twig +++ b/~dev_rating/application/views/student/subject.twig @@ -141,7 +141,7 @@ {% endif %} </div> - <div class="totalRate"> + <div class="Middle totalRate"> Промежуточный итог: {{ DisciplineMap.SemesterRate + DisciplineMap.ExtraRate }} / {{ DisciplineMap.SemesterMaxRate }} </div> @@ -187,7 +187,7 @@ {% endif %} </div> - <div class="totalRate"> + <div class="Final totalRate"> {% set Rating = DisciplineMap.SemesterRate + DisciplineMap.Extra.Rate + DisciplineMap.Bonus.Rate + DisciplineMap.Exam.Rate %} {% if Rating > 100 %} {% set Rating = 100 %} @@ -240,7 +240,7 @@ {% endif %} </div> - <div class="totalRate"> + <div class="Final totalRate"> {% set Rating = DisciplineMap.SemesterRate + DisciplineMap.Extra.Rate + DisciplineMap.Bonus.Rate %} {% if Rating > 100 %} {% set Rating = 100 %} -- GitLab