From 2e3439e86f9a11f5e3806b4df82fe2ae33679ae8 Mon Sep 17 00:00:00 2001 From: Artem Konenko <yadummer@gmail.com> Date: Fri, 29 Jul 2016 12:22:30 +0300 Subject: [PATCH] #127 Add refactored procedures & fixes to migrations --- db/migrations/V11_3__may's_fixes.sql | 15 + .../stored/V11_1__update_procedures.sql | 1431 +++++++++++ .../stored/V11_2__update_functions.sql | 2259 +++++++++++++++++ 3 files changed, 3705 insertions(+) create mode 100644 db/migrations/V11_3__may's_fixes.sql create mode 100644 db/migrations/stored/V11_1__update_procedures.sql create mode 100644 db/migrations/stored/V11_2__update_functions.sql diff --git a/db/migrations/V11_3__may's_fixes.sql b/db/migrations/V11_3__may's_fixes.sql new file mode 100644 index 000000000..ba2021667 --- /dev/null +++ b/db/migrations/V11_3__may's_fixes.sql @@ -0,0 +1,15 @@ +delete from `study_groups` WHERE GradeID in ( + select id from grades where Degree not in ('bachelor', 'specialist', 'master') +); +delete from grades where Degree not in ('bachelor', 'specialist', 'master'); + +-- recalculate CurRate in discipline table +update disciplines + inner join ( + select modules.DisciplineID, SUM(submodules.MaxRate) as rate + from submodules + inner join modules on submodules.ModuleID = modules.ID + where submodules.isUsed and (modules.Type = 'regular' or (modules.Type = 'exam' and modules.OrderNum = 1)) + group by modules.DisciplineID + ) as t on disciplines.ID = t.DisciplineID +set disciplines.CurRate = t.rate; diff --git a/db/migrations/stored/V11_1__update_procedures.sql b/db/migrations/stored/V11_1__update_procedures.sql new file mode 100644 index 000000000..bd457c488 --- /dev/null +++ b/db/migrations/stored/V11_1__update_procedures.sql @@ -0,0 +1,1431 @@ +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 */; + +DELIMITER // + +DROP PROCEDURE IF EXISTS Departments_LoadAll// +DROP PROCEDURE IF EXISTS GetSession // +DROP PROCEDURE IF EXISTS GetRatesExam// + +DROP FUNCTION IF EXISTS getStudentsForDisciplineT// +CREATE FUNCTION getStudentsForDisciplineT (pDisciplineID INT) RETURNS INT(11) +NO SQL + BEGIN + DECLARE vSemesterID INT DEFAULT -1; + SET vSemesterID = GetDisciplineProperty(pDisciplineID, 'semester'); + + + CREATE TEMPORARY TABLE tDisciplineStudents AS ( + SELECT st.StudentID, + COALESCE(st.Type) AS 'Type' + FROM ( + SELECT disciplines_students.StudentID, + disciplines_students.Type + FROM disciplines_students + WHERE disciplines_students.DisciplineID = pDisciplineID + UNION + SELECT students_groups.StudentID, + NULL AS 'Type' + FROM disciplines_groups + LEFT JOIN students_groups ON students_groups.SemesterID = vSemesterID AND + students_groups.GroupID = disciplines_groups.GroupID AND + students_groups.State <= 'outlet' + WHERE disciplines_groups.DisciplineID = pDisciplineID + ) as st + GROUP BY st.StudentID + ); + RETURN 0; + END // + + +DROP FUNCTION IF EXISTS getDisciplinesForStudentT// +CREATE FUNCTION getDisciplinesForStudentT(pStudentID INT, pSemesterID INT) RETURNS INT(11) +NO SQL + BEGIN + DECLARE vStudentGroup INT DEFAULT -1; + SET vStudentGroup = GetStudentGroup(pStudentID, pSemesterID); + + CREATE TEMPORARY TABLE IF NOT EXISTS tStudentDisciplines AS ( + SELECT disc2.DisciplineID + FROM ( + SELECT disc1.DisciplineID, + COALESCE(disc1.Type) AS 'Type' + FROM ( + SELECT disciplines_students.DisciplineID, + disciplines_students.Type + FROM disciplines_students + WHERE disciplines_students.StudentID = pStudentID + UNION + SELECT disciplines_groups.DisciplineID, + NULL AS 'Type' + FROM disciplines_groups + WHERE disciplines_groups.GroupID = vStudentGroup + ) AS disc1 + INNER JOIN disciplines ON disciplines.ID = disc1.DisciplineID + WHERE disciplines.SemesterID = pSemesterID + GROUP BY disc1.DisciplineID + ) AS disc2 + WHERE NOT disc2.Type <=> 'detach' + ); + RETURN 0; + END // + +# ------------------------------------------------------------------------------------------- +# Label: semesters +# ------------------------------------------------------------------------------------------- + +DROP PROCEDURE IF EXISTS GetSemestersInfo// +CREATE PROCEDURE GetSemestersInfo (IN pSemesterID INT) + SELECT semesters.* -- ID, Year, Num + FROM semesters + WHERE IF(pSemesterID != 0, semesters.ID = pSemesterID, TRUE) + ORDER BY semesters.ID DESC // + + + +# ------------------------------------------------------------------------------------------- +# Label: faculties +# ------------------------------------------------------------------------------------------- + +DROP PROCEDURE IF EXISTS GetFaculties// +CREATE PROCEDURE GetFaculties () + SELECT faculties.* -- ID, Abbr, Name + FROM faculties + ORDER BY faculties.Name ASC // + + +# ------------------------------------------------------------------------------------------- +# Label: departments +# ------------------------------------------------------------------------------------------- + +DROP PROCEDURE IF EXISTS GetDepartments// +CREATE PROCEDURE GetDepartments (IN pFacultyID INT) + BEGIN + IF pFacultyID <=> 0 THEN + SELECT departments.* FROM departments + ORDER BY departments.Name ASC; + ELSE + SELECT departments.* -- ID, Name, FacultyID + FROM departments + WHERE departments.FacultyID = pFacultyID + ORDER BY departments.Name ASC; + END IF; + END // + + + +# ------------------------------------------------------------------------------------------- +# Label: specializations +# ------------------------------------------------------------------------------------------- + +DROP PROCEDURE IF EXISTS GetSpecializations// +CREATE PROCEDURE GetSpecializations (IN pFacultyID INT) + SELECT specializations.* -- ID, Name, Abbr, FacultyID + FROM specializations + WHERE specializations.FacultyID = pFacultyID + ORDER BY subjects.Name ASC // + + +# ------------------------------------------------------------------------------------------- +# Label: job positions +# ------------------------------------------------------------------------------------------- + +DROP PROCEDURE IF EXISTS GetJobPositions// +CREATE PROCEDURE GetJobPositions () + SELECT job_positions.* -- ID, Name + FROM job_positions + ORDER BY job_positions.Name // + + +# ------------------------------------------------------------------------------------------- +# Label: grades +# ------------------------------------------------------------------------------------------- + +DROP PROCEDURE IF EXISTS GetGrades// +CREATE PROCEDURE GetGrades () + SELECT grades.* -- ID, Num, Degree + FROM grades + ORDER BY grades.ID // + + + +# ------------------------------------------------------------------------------------------- +# Label: study groups +# ------------------------------------------------------------------------------------------- + +DROP PROCEDURE IF EXISTS GetGroups// +CREATE PROCEDURE GetGroups ( + IN pGradeID INT, + IN pFacultyID INT) + BEGIN + SELECT view_groups.GroupID AS 'ID', + view_groups.GroupNum, + view_groups.SpecID, + view_groups.SpecName, + view_groups.SpecAbbr + FROM view_groups + WHERE view_groups.GradeID = pGradeID AND + view_groups.FacultyID = pFacultyID + ORDER BY view_groups.GroupNum ASC; + END // + + +# get all groups, include attached student's groups +DROP PROCEDURE IF EXISTS GetGroupsForDisciplineAll// +CREATE PROCEDURE GetGroupsForDisciplineAll (IN pDisciplineID INT) + BEGIN + DECLARE vSemesterID INT DEFAULT -1; + SET vSemesterID = GetDisciplineProperty(pDisciplineID, 'semester'); + + # general + attached + CREATE TEMPORARY TABLE IF NOT EXISTS tGroup AS ( + SELECT tGroup1.GroupID + FROM ( + SELECT students_groups.GroupID + FROM disciplines_students + INNER JOIN students_groups ON students_groups.StudentID = disciplines_students.StudentID AND + students_groups.SemesterID = vSemesterID AND + students_groups.State <= 'outlet' + WHERE disciplines_students.DisciplineID = pDisciplineID AND + disciplines_students.Type = 'attach' + UNION + SELECT disciplines_groups.GroupID + FROM disciplines_groups + WHERE disciplines_groups.DisciplineID = pDisciplineID + ) tGroup1 + ); + + SELECT view_groups.GroupID AS 'ID', + view_groups.GroupNum, + view_groups.GradeID, + view_groups.GradeNum, + view_groups.Degree, + view_groups.SpecID, + view_groups.SpecName, + view_groups.SpecAbbr + FROM tGroup + INNER JOIN view_groups ON tGroup.GroupID = view_groups.GroupID + ORDER BY view_groups.GradeID ASC, view_groups.GroupID ASC; + END // + + +# get all general study groups, that takes this course +DROP PROCEDURE IF EXISTS GetGroupsForDiscipline// +CREATE PROCEDURE GetGroupsForDiscipline (IN pDisciplineID INT) + BEGIN + SELECT view_groups.GroupID AS 'ID', + view_groups.GroupNum, + view_groups.GradeID, + view_groups.GradeNum, + view_groups.Degree, + view_groups.SpecID, + view_groups.SpecName, + view_groups.SpecAbbr + FROM disciplines_groups + INNER JOIN view_groups ON disciplines_groups.GroupID = view_groups.GroupID + WHERE disciplines_groups.DisciplineID = pDisciplineID + ORDER BY view_groups.GradeID ASC, view_groups.GroupID ASC; + END // + + + +# ------------------------------------------------------------------------------------------- +# Label: subjects +# ------------------------------------------------------------------------------------------- + +DROP PROCEDURE IF EXISTS GetSubjects// +CREATE PROCEDURE GetSubjects (IN pFacultyID INT) + BEGIN + SELECT subjects.ID, + subjects.Name AS 'Title', + subjects.Abbr + FROM subjects_faculties + INNER JOIN subjects ON subjects_faculties.SubjectID = subjects.ID + WHERE subjects_faculties.FacultyID = pFacultyID + ORDER BY subjects.Name ASC; + END // + + + +# ------------------------------------------------------------------------------------------- +# Label: accounts +# ------------------------------------------------------------------------------------------- + +DROP PROCEDURE IF EXISTS GetFullInfo// +CREATE PROCEDURE GetFullInfo ( + IN pUserID INT, + IN pSemesterID INT) + BEGIN + DECLARE vAccountType enum('student', 'teacher'); + + SELECT user_roles.Type INTO vAccountType + FROM accounts + INNER JOIN user_roles ON accounts.UserRoleID = user_roles.ID + WHERE accounts.ID = pUserID + LIMIT 1; + + # type 1: student + # 2: teacher + IF vAccountType = 'student' THEN + SELECT + # personal info + students.LastName, + students.FirstName, + students.SecondName, + students.ID as 'StudentID', + + # group info + -- GradeID, GradeNum, GroupID, GroupNum, GroupName, Degree, + -- SpecID, SpecName, SpecAbbr, FacultyID, FacultyName, FacultyAbbr, + view_groups.*, + students_groups.SemesterID, + + # account info + accounts.ID, + accounts.Login, + accounts.EMail, + user_roles.Type, + user_roles.RoleName AS 'Role', + user_roles.Mark AS 'RoleMark', + accounts.IsEnabled, + accounts.ActivationCode AS 'Code', + accounts.UserAgent + FROM students + INNER JOIN accounts ON accounts.ID = students.AccountID + INNER JOIN user_roles ON user_roles.ID = accounts.UserRoleID + LEFT JOIN students_groups ON students.ID = students_groups.StudentID + LEFT JOIN view_groups ON view_groups.GroupID = students_groups.GroupID + WHERE students.AccountID = pUserID + ORDER BY students_groups.SemesterID <=> pSemesterID DESC + LIMIT 1; + ELSE + SELECT # teacher info + view_teachers.LastName, + view_teachers.FirstName, + view_teachers.SecondName, + view_teachers.TeacherID, + view_teachers.DepID, + view_teachers.DepName, + view_teachers.JobPositionName, + view_teachers.FacultyID, + view_teachers.FacultyName, + view_teachers.FacultyAbbr, + # account info + accounts.ID, + accounts.Login, + accounts.EMail, + user_roles.Type, + user_roles.RoleName AS 'Role', + user_roles.Mark AS 'RoleMark', + accounts.IsEnabled, + accounts.ActivationCode AS 'Code', + accounts.UserAgent + FROM view_teachers + INNER JOIN accounts ON accounts.ID = view_teachers.AccountID + INNER JOIN user_roles ON user_roles.ID = accounts.UserRoleID + WHERE view_teachers.AccountID = pUserID + LIMIT 1; + END IF; + END // + + + +# ------------------------------------------------------------------------------------------- +# Label: teachers +# ------------------------------------------------------------------------------------------- + +DROP PROCEDURE IF EXISTS GetTeachers// +CREATE PROCEDURE GetTeachers ( + IN pFacultyID INT, + IN pDepartmentID INT) + BEGIN + SELECT view_teachers.TeacherID AS 'ID', + view_teachers.LastName, + view_teachers.FirstName, + view_teachers.SecondName, + view_teachers.AccountID, + view_teachers.JobPositionName, + view_teachers.DepID, + view_teachers.DepName + FROM view_teachers + WHERE + CASE WHEN pFacultyID != 0 THEN view_teachers.FacultyID = pFacultyID ELSE TRUE END AND + CASE WHEN pDepartmentID != 0 THEN view_teachers.DepID = pDepartmentID ELSE TRUE END + ORDER BY view_teachers.LastName ASC, + view_teachers.FirstName ASC; + END // + + +# get teachers, that teach course +DROP PROCEDURE IF EXISTS GetTeachersForDiscipline// +CREATE PROCEDURE GetTeachersForDiscipline(IN pDisciplineID INT) + BEGIN + DECLARE vAuthorID INT DEFAULT -1; + SET vAuthorID = GetDisciplineProperty(pDisciplineID, 'author'); + + SELECT view_teachers.TeacherID AS 'ID', + view_teachers.LastName, + view_teachers.FirstName, + view_teachers.SecondName, + view_teachers.JobPositionID, + view_teachers.JobPositionName, + view_teachers.DepID, + view_teachers.DepName, + view_teachers.FacultyID, + view_teachers.FacultyAbbr, + ( view_teachers.TeacherID = vAuthorID ) AS 'IsAuthor' + FROM disciplines_teachers + INNER JOIN view_teachers ON view_teachers.TeacherID = disciplines_teachers.TeacherID + WHERE disciplines_teachers.DisciplineID = pDisciplineID + ORDER BY view_teachers.TeacherID = vAuthorID DESC, + view_teachers.LastName ASC, + view_teachers.FirstName ASC; + END // + +DROP PROCEDURE IF EXISTS GetTeachersListForStudent// +CREATE PROCEDURE GetTeachersListForStudent ( + IN pStudentID INT, + IN pSemesterID INT, + IN pLoadAll INT) + BEGIN + DECLARE vRes, vStudentGroup INT DEFAULT -1; + SET vStudentGroup = GetStudentGroup(pStudentID, pSemesterID); + + DROP TABLE IF EXISTS tStudentDisciplines; + SET vRes = getDisciplinesForStudentT(pStudentID, pSemesterID); + + SELECT tStudentDisciplines.DisciplineID, + teachers.ID AS 'TeacherID', + teachers.LastName, + teachers.FirstName, + teachers.SecondName + FROM tStudentDisciplines + INNER JOIN disciplines ON disciplines.ID = tStudentDisciplines.DisciplineID + LEFT JOIN disciplines_teachers ON disciplines_teachers.DisciplineID = tStudentDisciplines.DisciplineID + INNER JOIN teachers ON teachers.ID = disciplines_teachers.TeacherID + WHERE pLoadAll OR disciplines.Subtype IS NULL + ORDER BY tStudentDisciplines.DisciplineID ASC, + teachers.LastName ASC, + teachers.FirstName ASC; + END // + + + +# get teachers, that don't teach course +DROP PROCEDURE IF EXISTS SearchTeachers// +CREATE PROCEDURE SearchTeachers ( + IN pFacultyID INT, + IN pDepartmentID INT, + IN pWord1 VARCHAR(100) CHARSET utf8, + IN pWord2 VARCHAR(100) CHARSET utf8, + IN pWord3 VARCHAR(100) CHARSET utf8, + IN pDisciplineID INT) + BEGIN + DECLARE vWord1, vWord2, vWord3 VARCHAR(102) CHARSET utf8; + DECLARE vAuthorID INT DEFAULT -1; + + SET vWord1 = CONCAT('%', pWord1, '%'); + SET vWord2 = CONCAT('%', pWord2, '%'); + SET vWord3 = CONCAT('%', pWord3, '%'); + + SET vAuthorID = GetDisciplineProperty(pDisciplineID, 'author'); + + + DROP TABLE IF EXISTS tDiscTeachers; + CREATE TEMPORARY TABLE tDiscTeachers AS ( + SELECT disciplines_teachers.TeacherID + FROM disciplines_teachers + WHERE disciplines_teachers.DisciplineID <=> pDisciplineID + ); + + SELECT tTeachers.TeacherID AS 'ID', + tTeachers.LastName, + tTeachers.FirstName, + tTeachers.SecondName, + tTeachers.JobPositionName, + tTeachers.DepID, + tTeachers.DepName, + ( tTeachers.TeacherID = vAuthorID ) AS 'IsAuthor' + FROM view_teachers AS tTeachers + WHERE tTeachers.FacultyID = pFacultyID AND + CASE WHEN pDepartmentID != 0 THEN tTeachers.DepID = pDepartmentID ELSE TRUE END AND + NOT EXISTS ( + SELECT * FROM tDiscTeachers + WHERE tDiscTeachers.TeacherID = tTeachers.TeacherID + LIMIT 1 + ) AND + CASE WHEN pWord1 != '' AND + (@full := CONCAT(tTeachers.LastName, ' ', tTeachers.FirstName, ' ', tTeachers.SecondName)) != '' THEN + @full LIKE vWord1 AND + @full LIKE vWord2 AND + @full LIKE vWord3 + ELSE TRUE + END + ORDER BY tTeachers.FacultyID ASC, + tTeachers.DepName ASC, + tTeachers.LastName ASC, + tTeachers.FirstName ASC; + END // + + +# ------------------------------------------------------------------------------------------- +# Label: students +# ------------------------------------------------------------------------------------------- + +DROP PROCEDURE IF EXISTS GetStudents// +CREATE PROCEDURE GetStudents ( + IN pFacultyID INT, + IN pGradeID INT, + IN pGroupID INT, + IN pSemesterID INT, + IN pWord1 VARCHAR(100) CHARSET utf8, + IN pWord2 VARCHAR(100) CHARSET utf8, + IN pWord3 VARCHAR(100) CHARSET utf8) + BEGIN + DECLARE vWord1, vWord2, vWord3 VARCHAR(102) CHARSET utf8; + SET vWord1 = CONCAT('%', pWord1, '%'); + SET vWord2 = CONCAT('%', pWord2, '%'); + SET vWord3 = CONCAT('%', pWord3, '%'); + + + SELECT view_students.StudentID AS 'ID', + view_students.LastName, + view_students.FirstName, + view_students.SecondName, + view_students.AccountID, + view_students.GradeID, + view_students.GradeNum, + view_students.Degree, + view_students.GroupID, + view_students.GroupNum + FROM view_students + WHERE view_students.SemesterID = pSemesterID AND + CASE WHEN pFacultyID != 0 THEN view_students.FacultyID = pFacultyID ELSE TRUE END AND + CASE WHEN pGradeID != 0 THEN view_students.GradeID = pGradeID ELSE TRUE END AND + CASE WHEN pGroupID != 0 THEN view_students.GroupID = pGroupID ELSE TRUE END AND + CASE WHEN pWord1 != '' AND + (@full := CONCAT(view_students.LastName, ' ', view_students.FirstName, ' ', view_students.SecondName)) != '' THEN + @full LIKE vWord1 AND + @full LIKE vWord2 AND + @full LIKE vWord3 + ELSE TRUE + END + ORDER BY view_students.LastName ASC, + view_students.FirstName ASC; + END // + + +# not in general groups, not attached +DROP PROCEDURE IF EXISTS SearchStudents// +CREATE PROCEDURE SearchStudents ( + IN pGradeID INT, + IN pGroupID INT, + IN pFacultyID INT, + IN pFullName VARCHAR(100) CHARSET utf8, + IN pDisciplineID INT) + BEGIN + DECLARE vSemesterID, vRes INT DEFAULT -1; + DECLARE vFullNameReg VARCHAR(102) CHARSET utf8; + SET vSemesterID = GetDisciplineProperty(pDisciplineID, 'semester'); + SET vFullNameReg = CONCAT('%', pFullName, '%'); + + DROP TABLE IF EXISTS tDisciplineStudents; + SET vRes = getStudentsForDisciplineT(pDisciplineID); + + SELECT view_students.StudentID AS 'ID', + view_students.LastName, + view_students.FirstName, + view_students.SecondName, + view_students.GradeID, + view_students.GradeNum, + view_students.Degree, + view_students.GroupID, + view_students.GroupNum + FROM view_students + LEFT JOIN tDisciplineStudents ON tDisciplineStudents.StudentID = view_students.StudentID + WHERE view_students.SemesterID = vSemesterID AND + view_students.FacultyID = pFacultyID AND + view_students.GradeID = pGradeID AND + (pGroupID = 0 OR view_students.GroupID = pGroupID) AND + tDisciplineStudents.StudentID IS NULL AND + CASE WHEN pFullName != '' THEN + CONCAT(view_students.LastName, ' ', view_students.FirstName, ' ', view_students.SecondName) LIKE vFullNameReg + ELSE TRUE END + ORDER BY view_students.GradeID ASC, + view_students.GroupID ASC, + view_students.LastName ASC, + view_students.FirstName ASC; + END // + + + +# in general groups, attached or detached +DROP PROCEDURE IF EXISTS GetStudentsForDiscipline// +CREATE PROCEDURE GetStudentsForDiscipline ( + IN pDisciplineID INT) + BEGIN + DECLARE vSemesterID, vRes INT DEFAULT -1; + SET vSemesterID = GetDisciplineProperty(pDisciplineID, 'semester'); + + DROP TABLE IF EXISTS tDisciplineStudents; + SET vRes = getStudentsForDisciplineT(pDisciplineID); + + SELECT view_students.StudentID AS 'ID', + view_students.LastName, + view_students.FirstName, + view_students.SecondName, + view_students.GradeID, + view_students.GradeNum, + view_students.Degree, + view_students.GroupID, + view_students.GroupNum, + tDisciplineStudents.Type AS 'AttachType' + FROM tDisciplineStudents + INNER JOIN view_students ON view_students.StudentID = tDisciplineStudents.StudentID AND + view_students.SemesterID = vSemesterID + ORDER BY tDisciplineStudents.Type <=> 'attach' ASC, + view_students.GradeID ASC, + view_students.GroupNum ASC, + view_students.LastName ASC, + view_students.FirstName ASC; + END // + + +# in general groups + attached +DROP PROCEDURE IF EXISTS GetStudentsForRating// +CREATE PROCEDURE GetStudentsForRating ( + IN pDisciplineID INT) + BEGIN + DECLARE vSemesterID, vRes INT DEFAULT -1; + SET vSemesterID = GetDisciplineProperty(pDisciplineID, 'semester'); + + DROP TABLE IF EXISTS tDisciplineStudents; + SET vRes = getStudentsForDisciplineT(pDisciplineID); + + SELECT view_students.StudentID AS 'ID', + view_students.LastName, + view_students.FirstName, + view_students.SecondName, + view_students.GradeID, + view_students.GradeNum, + view_students.Degree, + view_students.GroupID, + view_students.GroupNum, + ( tDisciplineStudents.Type IS NOT NULL ) AS 'IsAttached' + FROM tDisciplineStudents + INNER JOIN view_students ON view_students.StudentID = tDisciplineStudents.StudentID AND + view_students.SemesterID = vSemesterID + WHERE NOT tDisciplineStudents.Type <=> 'detach' + ORDER BY view_students.GradeID ASC, + view_students.GroupNum ASC, + view_students.LastName ASC, + view_students.FirstName ASC; + END // + + + + + +# ------------------------------------------------------------------------------------------- +# Label: disciplines +# ------------------------------------------------------------------------------------------- + + +DROP PROCEDURE IF EXISTS GetDisciplineInfo// +DROP PROCEDURE IF EXISTS Discipline_GetInfo// +CREATE PROCEDURE Discipline_GetInfo ( + IN pDisciplineID INT) + BEGIN + DECLARE vIsBonus BOOLEAN; + SET vIsBonus = EXISTS( + SELECT * FROM modules + WHERE modules.DisciplineID = pDisciplineID AND + modules.Type = 'bonus' + LIMIT 1 + ); + + SELECT + view_disciplines.DisciplineID AS 'ID', + view_disciplines.AuthorID, + view_disciplines.GradeID, + view_disciplines.GradeNum, + view_disciplines.Degree, + view_disciplines.ExamType AS 'Type', + view_disciplines.LectureCount AS 'Lectures', + view_disciplines.PracticeCount AS 'Practice', + view_disciplines.LabCount AS 'Labs', + view_disciplines.SemesterID, + view_disciplines.SubjectID, + view_disciplines.SubjectName, + view_disciplines.SubjectAbbr, + view_disciplines.FacultyID, + view_disciplines.FacultyName, + view_disciplines.IsLocked, + view_disciplines.Milestone, + view_disciplines.Subtype, + view_disciplines.CompoundDiscID, + vIsBonus AS 'IsBonus', + semesters.Num AS 'semesterNum', # TODO: Camelize + semesters.Year AS 'semesterYear' + FROM view_disciplines + INNER JOIN semesters ON semesters.ID = view_disciplines.SemesterID + WHERE view_disciplines.DisciplineID = pDisciplineID + LIMIT 1; + END // + + +# all disciplines for faculty in current semester +DROP PROCEDURE IF EXISTS GetDisciplines// +CREATE PROCEDURE GetDisciplines ( + IN pFacultyID INT, + IN pSemesterID INT) + BEGIN + SELECT view_disciplines.DisciplineID AS 'ID', + view_disciplines.SubjectID, + view_disciplines.SubjectName, + view_disciplines.ExamType AS 'Type', + (view_disciplines.MaxRate = 100) AS 'isMapCreated' + FROM view_disciplines + WHERE view_disciplines.SemesterID = pSemesterID AND + view_disciplines.FacultyID = pFacultyID + ORDER BY view_disciplines.SubjectName ASC; + END // + +DROP PROCEDURE IF EXISTS GetCompoundDisciplinesForGrade// +CREATE PROCEDURE GetCompoundDisciplinesForGrade ( + IN pGradeID INT) + BEGIN + SELECT compound_disciplines.ID, + compound_disciplines.Name + FROM compound_disciplines + WHERE compound_disciplines.GradeID = pGradeID; + END // + +# processed format of output (after desequentialization) +# { discipline1 {group1, group2, ...}, discipline2 {groupN, ...}, ... } +DROP PROCEDURE IF EXISTS GetDisciplinesForTeacher// +CREATE PROCEDURE GetDisciplinesForTeacher ( + IN pTeacherID INT, + IN pSemesterID INT) + BEGIN + SELECT DISTINCT view_disciplines.DisciplineID AS 'ID', + view_disciplines.ExamType AS 'Type', + view_disciplines.Subtype, + view_disciplines.GradeID, + view_disciplines.GradeNum, + view_disciplines.Degree, + view_groups.GroupID, + view_groups.GroupNum, + view_groups.GroupName, + view_disciplines.SubjectID, + view_disciplines.SubjectName, + view_disciplines.AuthorID, + view_disciplines.IsLocked AS 'IsLocked', -- bodging, db schema remembered lowerCase + (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 + INNER JOIN view_disciplines ON disciplines_teachers.DisciplineID = view_disciplines.DisciplineID + WHERE disciplines_teachers.TeacherID = pTeacherID AND view_disciplines.SemesterID = pSemesterID + ORDER BY view_disciplines.GradeID ASC, + view_disciplines.SubjectName ASC, + view_disciplines.DisciplineID ASC, + view_groups.GroupNum ASC; + END // + + +# get all disciplines, that student take. +DROP PROCEDURE IF EXISTS GetDisciplinesForStudent// +CREATE PROCEDURE GetDisciplinesForStudent ( + IN pStudentID INT, + IN pSemesterID INT) + BEGIN + DECLARE vRes INT DEFAULT -1; + DROP TABLE IF EXISTS tStudentDisciplines; + SET vRes = getDisciplinesForStudentT(pStudentID, pSemesterID); + + # only Cthulhu knows, what happened here + SELECT view_disciplines.DisciplineID AS 'ID', + view_disciplines.SubjectID, + view_disciplines.SubjectName, + view_disciplines.ExamType AS 'Type', + view_disciplines.Subtype, + teachers.LastName, + teachers.FirstName, + teachers.SecondName, + ( tDR.RateExam + tDR.RateMExam ) AS 'Rate', + ( tDR.MaxRegularRate + tDR.MaxExamRate ) AS 'MaxCurrentRate' + FROM ( + SELECT tRating.DisciplineID, + SUM( + IF( tRating.SubmoduleIsUsed AND tRating.ModuleType <=> 'regular', + tRating.SubmoduleRate, 0) + ) AS 'MaxRegularRate', + MAX( + IF( tRating.SubmoduleIsUsed AND tRating.ModuleType <=> 'exam', + tRating.SubmoduleRate, 0) + ) AS 'MaxExamRate', + SUM(IF(NOT tRating.ModuleType <=> 'exam', tRating.Rate, 0)) AS 'RateMExam', + MAX(IF(tRating.ModuleType <=> 'exam' AND tRating.Rate IS NOT NULL, tRating.Rate, 0)) AS 'RateExam' + FROM ( + SELECT tStudentDisciplines.DisciplineID, + vr.SubmoduleRate, + vr.ModuleType, + rt.Rate, + vr.SubmoduleIsUsed + FROM tStudentDisciplines as tStudentDisciplines + LEFT JOIN view_roadmap AS vr ON vr.DisciplineID = tStudentDisciplines.DisciplineID + LEFT JOIN rating_table AS rt ON rt.StudentID = pStudentID AND + rt.SubmoduleID = vr.SubmoduleID + ) AS tRating + GROUP BY tRating.DisciplineID + ) AS tDR + INNER JOIN view_disciplines ON view_disciplines.DisciplineID = tDR.DisciplineID + INNER JOIN teachers ON teachers.ID = view_disciplines.AuthorID + ORDER BY view_disciplines.ExamType ASC, view_disciplines.SubjectName ASC; + END // + + +# get all disciplines for group, including disciplines, where students have attached status +DROP PROCEDURE IF EXISTS GetDisciplinesForGroup// +CREATE PROCEDURE GetDisciplinesForGroup ( + IN pGroupID INT, + IN pSemesterID INT) + BEGIN + + # Get all attached groups for disc + DROP TABLE IF EXISTS tDisc; + CREATE TEMPORARY TABLE tDisc AS ( + SELECT tTemp.DisciplineID + FROM ( + SELECT disciplines_groups.DisciplineID + FROM disciplines_groups + WHERE disciplines_groups.GroupID = pGroupID + UNION + SELECT DISTINCT disciplines_students.DisciplineID + FROM students_groups + LEFT JOIN disciplines_students ON disciplines_students.StudentID = students_groups.StudentID + WHERE students_groups.GroupID = pGroupID AND + students_groups.SemesterID = pSemesterID AND + students_groups.State <= 'outlet' AND + disciplines_students.Type <=> 'attach' + ) AS tTemp + ); + + SELECT tDisc.DisciplineID AS 'ID', + view_disciplines.SubjectName, + view_disciplines.Subtype, + view_disciplines.ExamType AS 'Type', + view_disciplines.CompoundDiscID, + view_disciplines.CompoundDiscName, + view_disciplines.CurRate, + view_disciplines.MaxRate + FROM tDisc + INNER JOIN view_disciplines ON tDisc.DisciplineID = view_disciplines.DisciplineID + WHERE view_disciplines.SemesterID = pSemesterID; + END // + + +# ------------------------------------------------------------------------------------------- +# Label: rating +# ------------------------------------------------------------------------------------------- + +# TODO: merge with GetRatesForGroupByStage +DROP PROCEDURE IF EXISTS GetRatesForGroup// +CREATE PROCEDURE GetRatesForGroup ( + IN pDisciplineID INT, + IN pGroupID INT) + BEGIN + DECLARE vInGeneralGroup BOOLEAN DEFAULT FALSE; + DECLARE vSemesterID INT DEFAULT -1; + SET vSemesterID = GetDisciplineProperty(pDisciplineID, 'semester'); + + SET vInGeneralGroup = EXISTS( + SELECT * FROM disciplines_groups + WHERE disciplines_groups.DisciplineID = pDisciplineID AND + disciplines_groups.GroupID = pGroupID + LIMIT 1 + ); + + + DROP TABLE IF EXISTS tStudents; + CREATE TEMPORARY TABLE tStudents AS ( + SELECT students_groups.StudentID + FROM students_groups + LEFT JOIN disciplines_students ON disciplines_students.DisciplineID = pDisciplineID AND + disciplines_students.StudentID = students_groups.StudentID + WHERE students_groups.SemesterID = vSemesterID AND + students_groups.State <= 'outlet' AND # actual students + students_groups.GroupID = pGroupID AND + CASE WHEN vInGeneralGroup THEN + NOT disciplines_students.Type <=> 'detach' # not detached + ELSE + disciplines_students.Type <=> 'attach' # is attached + END + ); + + DROP TABLE IF EXISTS vRoadMap; + CREATE TEMPORARY TABLE vRoadMap AS ( + SELECT view_roadmap.SubmoduleID, + view_roadmap.ModuleType AS 'Type' + FROM view_roadmap + WHERE view_roadmap.DisciplineID = pDisciplineID + ); + + SELECT students.ID, + students.LastName, + students.FirstName, + students.SecondName, + vRates.RateRegular AS 'intermediate', + vRates.RateBonus AS 'bonus', + vRates.RateExam AS 'exam' + FROM ( + SELECT tStudents.StudentID, + SUM(IF(vRoadMap.Type = 'regular', rt.Rate, 0)) AS 'RateRegular', + SUM(IF(vRoadMap.Type = 'extra', rt.Rate, 0)) AS 'RateExtra', + SUM(IF(vRoadMap.Type = 'bonus', rt.Rate, 0)) AS 'RateBonus', + MAX(IF(vRoadMap.Type = 'exam', rt.Rate, 0)) AS 'RateExam' + FROM tStudents + CROSS JOIN vRoadMap + LEFT JOIN rating_table as rt ON rt.StudentID = tStudents.StudentID AND + rt.SubmoduleID = vRoadMap.SubmoduleID + GROUP BY tStudents.StudentID + ) vRates + INNER JOIN students ON students.ID = vRates.StudentID + ORDER BY CONCAT(students.LastName, students.FirstName, students.SecondName) ASC, students.ID ASC; + END // + + + +# TODO: merge with GetRatesForGroupByStage +DROP PROCEDURE IF EXISTS GetRatesForGroupAll// +CREATE PROCEDURE GetRatesForGroupAll ( + IN pGroupID INT, + IN pSemesterID INT) + BEGIN + DROP TABLE IF EXISTS tDisc; + CREATE TEMPORARY TABLE tDisc AS ( + SELECT tTemp.DisciplineID + FROM ( + SELECT disciplines_groups.DisciplineID + FROM disciplines_groups + WHERE disciplines_groups.GroupID = pGroupID + UNION + SELECT DISTINCT disciplines_students.DisciplineID + FROM students_groups + LEFT JOIN disciplines_students ON disciplines_students.StudentID = students_groups.StudentID + WHERE students_groups.GroupID = pGroupID AND + students_groups.State <= 'outlet' AND + disciplines_students.Type <=> 'attach' + ) AS tTemp + ); + + DROP TABLE IF EXISTS tStudents; + CREATE TEMPORARY TABLE tStudents AS ( + SELECT students_groups.StudentID + FROM students_groups + WHERE students_groups.GroupID = pGroupID + and students_groups.SemesterID = pSemesterID + ); + + DROP TABLE IF EXISTS vRoadMap; + CREATE TEMPORARY TABLE vRoadMap AS ( + SELECT tDisc.DisciplineID as 'DisciplineID', + view_roadmap.ModuleType as 'Type', + view_roadmap.SubmoduleID + FROM tDisc + LEFT JOIN view_roadmap ON view_roadmap.DisciplineID = tDisc.DisciplineID + ); + + SELECT vRates.StudentID as 'StudentID', + vRates.DisciplineID as 'DisciplineID', + disciplines.CompoundDiscID, + vRates.RateRegular AS 'intermediate', + vRates.RateBonus AS 'bonus', + vRates.RateExtra AS 'extra', + vRates.RateExam AS 'exam', + vRates.CntExam AS 'examCnt' + FROM ( + SELECT tStudents.StudentID, + vRoadMap.DisciplineID, + SUM(IF(vRoadMap.Type = 'regular', rt.Rate, 0)) AS 'RateRegular', + SUM(IF(vRoadMap.Type = 'extra', rt.Rate, 0)) AS 'RateExtra', + SUM(IF(vRoadMap.Type = 'bonus', rt.Rate, 0)) AS 'RateBonus', + MAX(IF(vRoadMap.Type = 'exam', rt.Rate, 0)) AS 'RateExam', + SUM(IF(vRoadMap.Type = 'exam', 1, 0)) AS 'CntExam' + FROM tStudents + CROSS JOIN vRoadMap + LEFT JOIN rating_table as rt ON rt.StudentID = tStudents.StudentID AND + rt.SubmoduleID = vRoadMap.SubmoduleID + WHERE rt.Rate IS NOT NULL + GROUP BY tStudents.StudentID, vRoadMap.DisciplineID + ) vRates + INNER JOIN students ON students.ID = vRates.StudentID + INNER JOIN disciplines ON disciplines.id = vRates.DisciplineID + ORDER BY CONCAT(students.LastName, students.FirstName, students.SecondName) ASC, + vRates.DisciplineID ASC; + END // + + +DROP PROCEDURE IF EXISTS GetRatesForGroupByStage// +CREATE PROCEDURE GetRatesForGroupByStage ( + IN pDisciplineID INT, + IN pGroupID INT, + IN pMilestone INT) + BEGIN + DECLARE vSemesterID, vGroupID INT DEFAULT -1; + DECLARE vInGeneralGroup BOOL DEFAULT FALSE; + 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; + SET vInGeneralGroup = EXISTS( + SELECT * FROM disciplines_groups + WHERE disciplines_groups.DisciplineID = pDisciplineID AND + disciplines_groups.GroupID = pGroupID + LIMIT 1 + ); + + + DROP TABLE IF EXISTS tStudents; + CREATE TEMPORARY TABLE tStudents AS ( + SELECT students_groups.StudentID + FROM students_groups + LEFT JOIN disciplines_students ON disciplines_students.DisciplineID = pDisciplineID AND + disciplines_students.StudentID = students_groups.StudentID + WHERE students_groups.SemesterID = vSemesterID AND + students_groups.State <= 'outlet' AND # actual students + students_groups.GroupID = pGroupID AND + CASE WHEN vInGeneralGroup THEN + NOT disciplines_students.Type <=> 'detach' # not detached + ELSE + disciplines_students.Type <=> 'attach' # is attached + END + ); + + 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(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 // + + +DROP PROCEDURE IF EXISTS GetRatesForDiscipline// +CREATE PROCEDURE GetRatesForDiscipline ( + IN pDisciplineID INT) + BEGIN + DECLARE vSemesterID INT DEFAULT -1; + SET vSemesterID = GetDisciplineProperty(pDisciplineID, 'semester'); + + SELECT view_roadmap.SubmoduleID, + rating_table.StudentID, + rating_table.Rate + FROM view_roadmap + LEFT JOIN rating_table ON rating_table.SubmoduleID = view_roadmap.SubmoduleID + INNER JOIN students_groups ON students_groups.SemesterID = vSemesterID AND + students_groups.StudentID = rating_table.StudentID + WHERE view_roadmap.DisciplineID = pDisciplineID + ORDER BY rating_table.StudentID; + END // + +# get rates for student +# returns only last rated exam submodule, or first, if not rated +DROP PROCEDURE IF EXISTS GetRates// +CREATE PROCEDURE GetRates ( + IN pStudentID INT, + IN pDisciplineID INT) + BEGIN + DECLARE vExamSubmoduleID INT DEFAULT GetExamRateID(pStudentID, pDisciplineID); + + SELECT vr.ModuleID, + vr.ModuleName, + vr.SubmoduleID, + vr.SubmoduleName, + vr.SubmoduleRate AS MaxRate, + vr.SubmoduleType AS SubmoduleControl, + vr.ModuleType, + rt.Rate, + rt.Date, + epo.Type AS ExamPeriodOption + FROM view_roadmap AS vr + LEFT JOIN rating_table AS rt ON vr.SubmoduleID = rt.SubmoduleID AND rt.StudentID = pStudentID + LEFT JOIN exam_period_options AS epo ON epo.SubmoduleID = rt.SubmoduleID AND epo.StudentID = pStudentID + WHERE vr.DisciplineID = pDisciplineID AND ( vr.ModuleType != 'exam' OR vr.SubmoduleID = vExamSubmoduleID ) + ORDER BY vr.ModuleType ^ 1 ASC, -- 1, 3, 2, 4 ASC + vr.ModuleOrderNum ASC, + vr.SubmoduleOrderNum ASC; + END // + + +DROP PROCEDURE IF EXISTS GetRatesAll// +CREATE PROCEDURE GetRatesAll ( + IN pStudentID INT, + IN pDisciplineID INT) + BEGIN + SELECT view_roadmap.ModuleID, + view_roadmap.ModuleName, + view_roadmap.SubmoduleID, + view_roadmap.SubmoduleName, + view_roadmap.SubmoduleRate AS 'MaxRate', + view_roadmap.SubmoduleType, + rating_table.Rate, + rating_table.Date, + view_roadmap.ModuleType, + exam_period_options.Type As ExamPeriodOption + FROM view_roadmap + LEFT JOIN rating_table ON rating_table.SubmoduleID = view_roadmap.SubmoduleID AND + rating_table.StudentID = pStudentID + LEFT JOIN exam_period_options ON exam_period_options.StudentID = pStudentID AND + exam_period_options.SubmoduleID = view_roadmap.SubmoduleID + WHERE view_roadmap.DisciplineID = pDisciplineID + ORDER BY view_roadmap.ModuleOrderNum ASC, + view_roadmap.SubmoduleOrderNum ASC; + END // + +DROP PROCEDURE IF EXISTS GetRatesHistory// +CREATE PROCEDURE GetRatesHistory ( + IN pDisciplineID INT) + BEGIN + SELECT logs_rating.ID, + logs_rating.Date, + logs_rating.Rate, + students.LastName AS 'StudentLast', + students.FirstName AS 'StudentFirst', + students.SecondName AS 'StudentSecond', + teachers.LastName AS 'TeacherLast', + teachers.FirstName AS 'TeacherFirst', + teachers.SecondName AS 'TeacherSecond', + submodules.Name AS 'SubmoduleName', + modules.Name AS 'ModuleName' + FROM logs_rating + INNER JOIN students ON students.ID = logs_rating.StudentID + INNER JOIN teachers ON teachers.ID = logs_rating.TeacherID + INNER JOIN submodules ON submodules.ID = logs_rating.SubmoduleID + INNER JOIN modules ON modules.ID = submodules.ModuleID + WHERE modules.DisciplineID = pDisciplineID; + END // + +DROP PROCEDURE IF EXISTS GetSignInHistory// +CREATE PROCEDURE `GetSignInHistory` ( + IN `pLimit` INT +) NO SQL + BEGIN + SELECT logs_signin.ID, + logs_signin.Date, + logs_signin.AccountID, + teachers.LastName, + teachers.FirstName, + teachers.SecondName + FROM `logs_signin` + INNER JOIN `teachers` ON teachers.AccountID = logs_signin.AccountID + ORDER BY logs_signin.Date DESC LIMIT pLimit; + END // + +DROP PROCEDURE IF EXISTS GetAttestationData// +CREATE PROCEDURE GetAttestationData ( + IN pDisciplineID INT, + IN pGroupID INT +) + BEGIN + DECLARE vSemesterID INT DEFAULT -1; + SET vSemesterID = GetDisciplineProperty(pDisciplineID, 'semester'); + + SELECT students.ID AS 'StudentID', + rating_table.Rate As 'Rate', + rating_table.Date As 'Date', + submodules.OrderNum As 'OrderNum', + modules.Type As 'Type' + FROM students + INNER JOIN students_groups ON students_groups.StudentID = students.ID AND + students_groups.SemesterID = vSemesterID AND + students_groups.State <= 'outlet' + + LEFT JOIN disciplines_groups ON disciplines_groups.DisciplineID = pDisciplineID AND + disciplines_groups.GroupID = students_groups.GroupID + LEFT JOIN disciplines_students ON disciplines_students.DisciplineID = pDisciplineID AND + disciplines_students.StudentID = students.ID + + LEFT JOIN modules ON modules.DisciplineID = pDisciplineID AND + (modules.Type = 'exam' OR modules.Type = 'extra') + LEFT JOIN submodules ON submodules.ModuleID = modules.ID + LEFT JOIN rating_table ON rating_table.SubmoduleID = submodules.ID AND + rating_table.StudentID = students.ID + WHERE students_groups.GroupID = pGroupID AND rating_table.Rate IS NOT NULL AND + ((disciplines_students.StudentID IS NOT NULL AND disciplines_students.Type = 'attach') + OR (disciplines_groups.DisciplineID IS NOT NULL AND disciplines_students.Type IS NULL) + ) + ORDER BY CONCAT(students.LastName, ' ', students.FirstName, ' ', students.SecondName) ASC, + students.ID ASC, + modules.Type = 'exam' ASC, + submodules.OrderNum ASC; + END // + + +# ------------------------------------------------------------------------------------------- +# Label: disciplines +# Label: roadmaps +# ------------------------------------------------------------------------------------------- + +# TODO: order hardcode +# TODO: deprecated +DROP PROCEDURE IF EXISTS GetRoadmap// +CREATE PROCEDURE GetRoadmap ( + IN pDisciplineID INT, + IN pType enum('exam', 'rate', 'all')) + BEGIN + SELECT view_roadmap.ModuleID, + view_roadmap.ModuleName, + view_roadmap.ModuleType, + view_roadmap.SubmoduleID, + view_roadmap.SubmoduleName, + view_roadmap.SubmoduleRate AS 'MaxRate', + view_roadmap.SubmoduleType + FROM view_roadmap + WHERE view_roadmap.DisciplineID = pDisciplineID AND + CASE pType + WHEN 'exam' THEN view_roadmap.ModuleType = 'exam' OR view_roadmap.ModuleType = 'extra' + WHEN 'rate' THEN view_roadmap.ModuleType != 'exam' OR view_roadmap.SubmoduleOrderNum = 1 + ELSE TRUE + END + ORDER BY + CASE pType + WHEN 'exam' THEN InternalOrderModuleTypesForSession(view_roadmap.ModuleType) + WHEN 'rate' THEN view_roadmap.ModuleType ^ 1 # 1, 3, 2, 4 ASC + ELSE TRUE + END ASC, + view_roadmap.ModuleOrderNum ASC, + view_roadmap.SubmoduleOrderNum ASC; + END // + + +DROP PROCEDURE IF EXISTS Discipline_GetModules// +CREATE PROCEDURE Discipline_GetModules ( + IN pDisciplineID INT, + IN pType enum('exam', 'rate', 'all')) + BEGIN + SELECT modules.ID, + modules.Name, + modules.Type + FROM modules + WHERE modules.DisciplineID = pDisciplineID AND + CASE pType + WHEN 'exam' THEN modules.Type = 'exam' OR modules.Type = 'extra' + WHEN 'rate' THEN modules.Type != 'exam' + ELSE TRUE + END + ORDER BY + CASE pType + WHEN 'exam' THEN InternalOrderModuleTypesForSession(modules.Type) + WHEN 'rate' THEN modules.Type ^ 1 # 1, 3, 2, 4 ASC + ELSE TRUE + END ASC, + modules.OrderNum ASC; + END // + + +DROP PROCEDURE IF EXISTS Discipline_GetSubmodules// +CREATE PROCEDURE Discipline_GetSubmodules ( + IN pDisciplineID INT, + IN pType enum('exam', 'rate', 'all')) + BEGIN + SELECT view_roadmap.ModuleID, + view_roadmap.SubmoduleID AS 'ID', + view_roadmap.SubmoduleName AS 'Name', + view_roadmap.SubmoduleRate AS 'Rate', + view_roadmap.SubmoduleType AS 'Type' + FROM view_roadmap + WHERE view_roadmap.DisciplineID = pDisciplineID AND + CASE pType + WHEN 'exam' THEN view_roadmap.ModuleType = 'exam' OR view_roadmap.ModuleType = 'extra' + WHEN 'rate' THEN view_roadmap.ModuleType != 'exam' OR view_roadmap.SubmoduleOrderNum = 1 + ELSE TRUE + END + ORDER BY + view_roadmap.ModuleOrderNum ASC, + view_roadmap.SubmoduleOrderNum ASC; + END // + + + +# ------------------------------------------------------------------------------------------- +# Label: recovery +# ------------------------------------------------------------------------------------------- + +DROP PROCEDURE IF EXISTS GetRecoveryInfoByToken// +CREATE PROCEDURE GetRecoveryInfoByToken(IN pToken VARCHAR(100) CHARSET utf8) + BEGIN + SELECT recovery_tokens.ID, + recovery_tokens.AccountID, + recovery_tokens.Date, + recovery_tokens.Token, + recovery_tokens.IsUsed + FROM recovery_tokens + WHERE recovery_tokens.Token = pToken + LIMIT 1; + END // + + + +DROP PROCEDURE IF EXISTS GetRecoveryInfoByEMail// +CREATE PROCEDURE GetRecoveryInfoByEMail(IN pEMail VARCHAR(255) CHARSET utf8) + BEGIN + SELECT recovery_tokens.ID, + recovery_tokens.AccountID, + recovery_tokens.Date, + recovery_tokens.Token, + recovery_tokens.IsUsed + FROM accounts + INNER JOIN recovery_tokens ON recovery_tokens.AccountID = accounts.ID + WHERE accounts.EMail = pEMail AND + recovery_tokens.IsUsed = 0 + LIMIT 1; + END // + + + + +# ------------------------------------------------------------------------------------------- +# Label: miscellaneous +# ------------------------------------------------------------------------------------------- + +DROP PROCEDURE IF EXISTS GetFinalFormInfo// +CREATE PROCEDURE GetFinalFormInfo ( + IN pDisciplineID INT, + IN pGroupID INT +) + BEGIN + SELECT study_groups.GroupNum AS 'GroupNum', + study_groups.Name AS 'GroupName', + grades.ID AS 'GradeID', + grades.Num AS 'GradeNum', + grades.Degree AS 'Degree', + specializations.ID AS 'SpecID', + specializations.Name AS 'SpecName', + specializations.Abbr AS 'SpecAbbr', + specializations.Code AS 'SpecCode', + faculties.ID AS 'FacultyID', + faculties.Name AS 'FacultyName', + faculties.Abbr AS 'FacultyAbbr', + disciplines.ExamType AS 'ExamType', + subjects.ID AS 'SubjectID', + subjects.Name AS 'SubjectName', + subjects.Abbr AS 'SubjectAbbr', + teachers.ID AS 'AuthorID', + teachers.LastName AS 'LastName', + teachers.FirstName AS 'FirstName', + teachers.SecondName AS 'SecondName', + job_positions.Name AS 'JobPosition', + departments.ID AS 'DepID', + departments.Name AS 'DepName', + semesters.Year AS 'Year', + semesters.Num AS 'SemesterNum' + FROM study_groups + INNER JOIN specializations ON study_groups.SpecializationID = specializations.ID + INNER JOIN grades ON study_groups.GradeID = grades.ID + INNER JOIN faculties ON faculties.ID = specializations.FacultyID + INNER JOIN disciplines ON disciplines.ID = pDisciplineID + INNER JOIN subjects ON disciplines.SubjectID = subjects.ID + INNER JOIN teachers ON teachers.ID = disciplines.AuthorID + INNER JOIN departments ON departments.ID = teachers.DepartmentID + INNER JOIN job_positions ON job_positions.ID = teachers.JobPositionID + INNER JOIN semesters ON disciplines.SemesterID = semesters.ID + WHERE study_groups.ID = pGroupID + LIMIT 1; + END // + + +DROP PROCEDURE IF EXISTS Student_GetInfo // +CREATE PROCEDURE Student_GetInfo(IN pID INT(11) ) + BEGIN + SELECT + view_students.StudentID AS 'ID', + view_students.LastName, + view_students.FirstName, + view_students.SecondName, + view_students.AccountID, + view_students.SemesterID, + view_students.GroupID, + view_students.GroupNum, + view_students.GroupName, + view_students.GradeID, + view_students.GradeNum, + view_students.Degree, + view_students.SpecID, + view_students.SpecName, + view_students.SpecAbbr, + view_students.SpecCode, + view_students.FacultyID, + view_students.FacultyName, + view_students.FacultyAbbr + FROM view_students WHERE pID = view_students.StudentID + LIMIT 1; + END // + +DROP PROCEDURE IF EXISTS Teacher_GetInfo // +CREATE PROCEDURE Teacher_GetInfo( IN pID INT(11) ) + SELECT view_teachers.TeacherID AS 'ID', + view_teachers.* + FROM view_teachers WHERE pID = view_teachers.TeacherID + LIMIT 1// + + +DROP PROCEDURE IF EXISTS GetRequests// +CREATE PROCEDURE GetRequests ( + IN pOffset INT, + IN pCount INT, + IN pAccountID INT, + IN pFilter enum('opened','processed','closed','all')) + BEGIN + SELECT requests.*, GetUserFullNameByAccountID(accounts.ID) as FullName, accounts.UserRoleID, + GetUserStudentOrTeacherID(AccountID, accounts.UserRoleID) as PersonalID + FROM requests join accounts on requests.AccountID = accounts.ID + WHERE IF(pFilter = 'all', TRUE, requests.Status = pFilter) AND + requests.Title != '' AND + requests.Description != '' + ORDER BY requests.Date DESC + LIMIT pCount OFFSET pOffset; + END// + +DROP PROCEDURE IF EXISTS RequestsNum// +CREATE PROCEDURE RequestsNum ( + IN pFilter enum('opened','processed','closed','all')) + BEGIN + SELECT COUNT(*) + AS Num + FROM requests + WHERE IF(pFilter = 'all', TRUE, requests.Status = pFilter) AND + requests.Title != '' AND + requests.Description != ''; + END// +DELIMITER ; diff --git a/db/migrations/stored/V11_2__update_functions.sql b/db/migrations/stored/V11_2__update_functions.sql new file mode 100644 index 000000000..c28829354 --- /dev/null +++ b/db/migrations/stored/V11_2__update_functions.sql @@ -0,0 +1,2259 @@ +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 */; + +DELIMITER // +DROP FUNCTION IF EXISTS SaveSession // +# ------------------------------------------------------------------------------------------- +# Label: internals +# ------------------------------------------------------------------------------------------- + +# actually check for first scoring, in this case you cannot yet edit discipline +# "SetRate" stored procedure can change isLocked flag +DROP FUNCTION IF EXISTS InternalIsMapLocked// +CREATE FUNCTION InternalIsMapLocked (pDisciplineID INT) RETURNS BOOLEAN +NO SQL + RETURN ( + SELECT disciplines.IsLocked FROM disciplines + WHERE disciplines.ID = pDisciplineID LIMIT 1 + ) <=> TRUE// + + +# check, that student really take this course +DROP FUNCTION IF EXISTS InternalIsStudentAttached// +CREATE FUNCTION InternalIsStudentAttached ( + pStudentID INT, + pDisciplineID INT +) RETURNS BOOLEAN +NO SQL + BEGIN + DECLARE vAttachType enum('attach','detach') DEFAULT NULL; + DECLARE vSemesterID, vGroupID INT DEFAULT 0; + + SET vSemesterID = GetDisciplineProperty(pDisciplineID, 'semester'); + + SELECT disciplines_students.Type INTO vAttachType + FROM disciplines_students + WHERE disciplines_students.StudentID = pStudentID AND + disciplines_students.DisciplineID = pDisciplineID + LIMIT 1; + IF vAttachType IS NOT NULL THEN # attached or detached + RETURN (vAttachType <=> 'attach'); + END IF; + + SET vGroupID = GetStudentGroup(pStudentID, vSemesterID); + RETURN EXISTS(SELECT * FROM disciplines_groups + WHERE disciplines_groups.GroupID = vGroupID + ); + END // + + +# check, that teacher teach this course +DROP FUNCTION IF EXISTS InternalIsTeacherBound// +CREATE FUNCTION InternalIsTeacherBound ( + pTeacherID INT, + pDisciplineID INT +) RETURNS BOOLEAN +NO SQL + RETURN EXISTS ( + SELECT * FROM disciplines_teachers + WHERE disciplines_teachers.TeacherID = pTeacherID AND disciplines_teachers.DisciplineID = pDisciplineID + LIMIT 1 + )// + + +DROP FUNCTION IF EXISTS InternalIsTeacherAuthor// +CREATE FUNCTION InternalIsTeacherAuthor ( + pTeacherID INT, + pDisciplineID INT +) RETURNS BOOLEAN +NO SQL + RETURN ( + SELECT disciplines.AuthorID FROM disciplines + WHERE disciplines.ID = pDisciplineID LIMIT 1 + ) <=> pTeacherID // + + +DROP FUNCTION IF EXISTS SetExamPeriodOption// +CREATE FUNCTION SetExamPeriodOption ( + pStudentID INT, + pSubmoduleID INT, + pType enum('absence','pass') +) RETURNS int(11) +NO SQL + BEGIN + DECLARE EXIT HANDLER FOR SQLEXCEPTION RETURN -1; + + INSERT INTO exam_period_options (StudentID, SubmoduleID, Type) VALUES(pStudentID, pSubmoduleID, pType) + ON DUPLICATE KEY UPDATE + exam_period_options.Type = pType; + RETURN 0; + END // + + +# check, regular + exam rate == 100 +DROP FUNCTION IF EXISTS InternalIsMapCreated// +CREATE FUNCTION InternalIsMapCreated (pDisciplineID INT +) RETURNS int(11) +NO SQL + RETURN ( + SELECT disciplines.MaxRate FROM disciplines + WHERE disciplines.ID = pDisciplineID LIMIT 1 + ) <=> 100// + + +# ordering helper +DROP FUNCTION IF EXISTS InternalOrderModuleTypesForSession// +CREATE FUNCTION InternalOrderModuleTypesForSession (pModuleType INT) RETURNS INT(3) +NO SQL + RETURN (CASE pModuleType + WHEN 4 THEN 1 # extra + WHEN 2 THEN 2 # exam + WHEN 3 THEN 3 # bonus + ELSE 4 + END)// + + +# ------------------------------------------------------------------------------------------- +# Label: user roles +# ------------------------------------------------------------------------------------------- + +-- todo: search by name +DROP FUNCTION IF EXISTS GetUserRole// +CREATE FUNCTION GetUserRole( + pType enum('student', 'teacher', 'admin', 'dean') +) RETURNS INT(11) +NO SQL + RETURN (CASE pType + WHEN 'dean' THEN 4 + WHEN 'teacher' THEN 2 + WHEN 'admin' THEN 3 + ELSE 1 + END)// + +# ------------------------------------------------------------------------------------------- +# Label: faculties +# ------------------------------------------------------------------------------------------- + +DROP FUNCTION IF EXISTS CreateFaculty // +CREATE FUNCTION CreateFaculty ( + pFacultyName TEXT CHARSET utf8, + pFacultyAbbr TEXT CHARSET utf8 +) RETURNS INT(11) # -1 or id +NO SQL + BEGIN + DECLARE EXIT HANDLER FOR SQLEXCEPTION RETURN -1; + + INSERT INTO faculties (Name, Abbr) VALUES (pFacultyName, pFacultyAbbr); + RETURN LAST_INSERT_ID(); + END// + +# ------------------------------------------------------------------------------------------- +# Label: departments +# ------------------------------------------------------------------------------------------- + +# create department or return existing +DROP FUNCTION IF EXISTS CreateDepartment // +DROP FUNCTION IF EXISTS Department_Create // +CREATE FUNCTION Department_Create ( + pName VARCHAR(200) CHARSET utf8, + pFacultyID INT(11) +) RETURNS INT(11) # department id or -1 if failed +NO SQL + BEGIN + DECLARE EXIT HANDLER FOR SQLEXCEPTION RETURN -1; + + INSERT INTO departments (Name, FacultyID) VALUES (pName, pFacultyID) + ON DUPLICATE KEY UPDATE + departments.ID = LAST_INSERT_ID(departments.ID); + RETURN LAST_INSERT_ID(); + END // + +DROP FUNCTION IF EXISTS Department_Search // +CREATE FUNCTION Department_Search ( + pName VARCHAR(200) CHARSET utf8, + pFacultyID INT(11) +) RETURNS INT(11) # department id of -1 if not found +NO SQL + RETURN COALESCE(( + SELECT departments.ID FROM departments + WHERE departments.Name = pName AND departments.FacultyID = pFacultyID LIMIT 1 + ), -1)// + + +# ------------------------------------------------------------------------------------------- +# Label: grades +# ------------------------------------------------------------------------------------------- + +DROP FUNCTION IF EXISTS CreateGrade// +CREATE FUNCTION CreateGrade ( + pGradeNum INT, + pDegree enum('bachelor', 'master', 'specialist') +) RETURNS int(11) # groupID or -1 if failed +NO SQL + BEGIN + DECLARE EXIT HANDLER FOR SQLEXCEPTION RETURN -1; + IF pDegree IS NULL OR NOT (pDegree BETWEEN 'bachelor' AND 'specialist') THEN + RETURN -1; + END IF; + + INSERT INTO grades (Num, Degree) VALUES (pGradeNum, pDegree) + ON DUPLICATE KEY UPDATE + grades.ID = LAST_INSERT_ID(grades.ID); + RETURN LAST_INSERT_ID(); + END // + +# ------------------------------------------------------------------------------------------- +# Label: groups +# ------------------------------------------------------------------------------------------- + + +# negative int, if already exists +DROP FUNCTION IF EXISTS CreateGroup// +CREATE FUNCTION CreateGroup ( + pGradeID INT, + pGroupNum INT, + pSpecializationID INT, + pGroupName VARCHAR(50) CHARSET utf8 +) RETURNS int(11) # group id +NO SQL + BEGIN + DECLARE EXIT HANDLER FOR SQLEXCEPTION RETURN -1; + + # create discipline + INSERT INTO study_groups (GradeID, GroupNum, SpecializationID, Name) VALUES + (pGradeID, pGroupNum, pSpecializationID, pGroupName) + ON DUPLICATE KEY UPDATE + study_groups.ID = LAST_INSERT_ID(study_groups.ID); + RETURN LAST_INSERT_ID(); + END // + + +DROP FUNCTION IF EXISTS GetGroup// +CREATE FUNCTION GetGroup ( + pGradeID INT, + pGroupNum INT, + pFacultyID INT +) RETURNS int(11) # groupID or -1 if failed +NO SQL + RETURN COALESCE(( + SELECT study_groups.ID FROM study_groups + INNER JOIN specializations ON specializations.ID = study_groups.SpecializationID + WHERE study_groups.GradeID = pGradeID + AND study_groups.GroupNum = pGroupNum + AND specializations.FacultyID = pFacultyID + LIMIT 1 + ), -1)// + + +DROP FUNCTION IF EXISTS GetStudentGroup// +CREATE FUNCTION GetStudentGroup ( + pStudentID INT, + pSemesterID INT +) RETURNS int(11) # groupID or -1 if failed +NO SQL + RETURN COALESCE(( + SELECT students_groups.GroupID FROM students_groups + WHERE students_groups.StudentID = pStudentID + AND students_groups.SemesterID = pSemesterID + AND students_groups.State != 'expulsion' + LIMIT 1 + ), -1)// + + +# ------------------------------------------------------------------------------------------- +# Label: subjects +# ------------------------------------------------------------------------------------------- + +DROP FUNCTION IF EXISTS CreateSubject// +CREATE FUNCTION CreateSubject ( + pFacultyID INT, + pSubjectName TEXT CHARSET utf8, + pSubjectAbbr VARCHAR(20) CHARSET utf8 +) RETURNS int(11) -- subjectID or negative value +NO SQL + BEGIN + DECLARE vSubjectID INT DEFAULT -1; + IF pSubjectName = '' THEN RETURN -1; END IF; + + # create/get subject (subject name is unique key) + INSERT INTO subjects (Name, Abbr) VALUES (pSubjectName, pSubjectAbbr) + ON DUPLICATE KEY UPDATE + subjects.ID = LAST_INSERT_ID(subjects.ID); + SET vSubjectID = LAST_INSERT_ID(); + + BEGIN # handler block + DECLARE EXIT HANDLER FOR SQLEXCEPTION RETURN -1; + INSERT INTO subjects_faculties (SubjectID, FacultyID) VALUES (vSubjectID, pFacultyID) + ON DUPLICATE KEY UPDATE # just stub + subjects_faculties.ID = LAST_INSERT_ID(subjects_faculties.ID); + END; + RETURN vSubjectID; + END // + + +DROP FUNCTION IF EXISTS DeleteSubject // +CREATE FUNCTION DeleteSubject (pSubjectID INT) RETURNS INT(11) +NO SQL + BEGIN + DECLARE vSubjectUsage BOOLEAN DEFAULT FALSE; + DECLARE EXIT HANDLER FOR SQLEXCEPTION RETURN -1; + + SET vSubjectUsage = EXISTS( + SELECT * FROM disciplines + WHERE disciplines.SubjectID = pSubjectID LIMIT 1 + ); + IF vSubjectUsage THEN + RETURN -1; # УдалÑемый предмет иÑпользуетÑÑ Ð² disciplines. + END IF; + + DELETE FROM subjects_faculties + WHERE subjects_faculties.SubjectID = pSubjectID; + DELETE FROM subjects + WHERE subjects.ID = pSubjectID + LIMIT 1; + + RETURN 0; # УÑпешно удалено; + END // + + +# ------------------------------------------------------------------------------------------- +# Label: accounts +# ------------------------------------------------------------------------------------------- + +-- todo: check php usage +DROP FUNCTION IF EXISTS CheckAccountExistence// +CREATE FUNCTION CheckAccountExistence ( + pData TEXT CHARSET utf8, + pType enum('login','email', 'code') +) RETURNS BOOLEAN # TRUE - exist, FALSE - doesn't +NO SQL + RETURN EXISTS( + SELECT * FROM accounts + WHERE CASE pType + WHEN 'login' THEN pData = accounts.Login + WHEN 'email' THEN pData = accounts.EMail + WHEN 'code' THEN pData = accounts.ActivationCode + ELSE FALSE + END + LIMIT 1 + )// + + +DROP FUNCTION IF EXISTS CreateAccount// +CREATE FUNCTION CreateAccount ( + pCode varchar(40) CHARSET utf8, + pUserRoleID int +) RETURNS int(11) +NO SQL + BEGIN + INSERT INTO accounts (Login , Password , EMail, UserRoleID, ActivationCode) + VALUES ( NULL, NULL, NULL, pUserRoleID, pCode); + RETURN LAST_INSERT_ID(); + END// + + +# return: +# -1 - unknown error. +# -2 - code doesn't exists. +# -3 - email already registered. +# -4 - login already registered. +DROP FUNCTION IF EXISTS ActivateAccount// +CREATE FUNCTION ActivateAccount ( + pCode VARCHAR(40) CHARSET utf8, + pLogin VARCHAR(50) CHARSET utf8, + pEMail VARCHAR(50) CHARSET utf8, + pPassword VARCHAR(255) CHARSET utf8 +) RETURNS int(11) +NO SQL + BEGIN + # check for matching with existing accounts (note: Login & E-Mail are unique) + DECLARE EXIT HANDLER FOR SQLEXCEPTION RETURN -1; + + IF CheckAccountExistence(pEMail, 'email') THEN + RETURN -3; + END IF; + IF CheckAccountExistence(pLogin, 'login') THEN + RETURN -4; + END IF; + + # activate account + UPDATE accounts + SET accounts.Login = pLogin, + accounts.Password = SHA1(pPassword), + accounts.EMail = pEMail, + accounts.ActivationCode = NULL + WHERE accounts.ActivationCode = pCode AND ( @vAccountID := accounts.ID ) # save accountID + LIMIT 1; + + RETURN IF(ROW_COUNT() = 0, -2, @vAccountID); # account with this Code not found + END // + + +DROP FUNCTION IF EXISTS ChangeAccountData// +CREATE FUNCTION ChangeAccountData ( + pUserID INT, + pData TEXT CHARSET utf8, + pType enum('login', 'email', 'password') +) RETURNS int(11) # 1 - success, 0 - failed +NO SQL + BEGIN + DECLARE EXIT HANDLER FOR SQLEXCEPTION RETURN 0; + + CASE pType + WHEN 'login' THEN + UPDATE accounts + SET accounts.Login = pData + WHERE accounts.ID = pUserID + LIMIT 1; + WHEN 'email' THEN + UPDATE accounts + SET accounts.EMail = pData + WHERE accounts.ID = pUserID + LIMIT 1; + WHEN 'password' THEN + UPDATE accounts + SET accounts.Password = SHA1(pData) + WHERE accounts.ID = pUserID + LIMIT 1; + END CASE; + + RETURN 1; + END // + + + +DROP FUNCTION IF EXISTS SignIn// +CREATE FUNCTION SignIn ( + pLoginOrMail VARCHAR(255) CHARSET utf8, + pPassword VARCHAR(64) CHARSET utf8 +) RETURNS int(11) # account id +NO SQL + BEGIN + DECLARE vAccountID INT DEFAULT -1; + + #check account existence + SELECT accounts.ID INTO vAccountID FROM accounts + WHERE accounts.Password = SHA1(pPassword) AND + (accounts.Login = pLoginOrMail OR accounts.EMail = pLoginOrMail) + LIMIT 1; + IF vAccountID <= 0 THEN + RETURN -1; + END IF; + + INSERT INTO logs_signin (AccountID) VALUES (vAccountID); + RETURN vAccountID; + END // + + + + +# ------------------------------------------------------------------------------------------- +# Label: teachers +# ------------------------------------------------------------------------------------------- + +DROP FUNCTION IF EXISTS ChangeTeacherInfo// +CREATE FUNCTION ChangeTeacherInfo ( + pTeacherID INT, + pLastName VARCHAR(30) CHARSET utf8, + pFirstName VARCHAR(30) CHARSET utf8, + pSecondName VARCHAR(30) CHARSET utf8, + pJobPositionID INT, + pDepartmentID INT +) RETURNS int(11) # -1 if teacher doesn't exists, otherwise 0 +NO SQL + BEGIN + DECLARE EXIT HANDLER FOR SQLEXCEPTION RETURN -1; + + # set new info + UPDATE teachers + SET teachers.LastName = pLastName, + teachers.FirstName = pFirstName, + teachers.SecondName = pSecondName, + teachers.JobPositionID = pJobPositionID, + teachers.DepartmentID = pDepartmentID + WHERE teachers.ID = pTeacherID + LIMIT 1; + RETURN ROW_COUNT()-1; + END // + + +DROP FUNCTION IF EXISTS Teacher_Create// +CREATE FUNCTION Teacher_Create ( + pLastName VARCHAR(30) CHARSET utf8, + pFirstName VARCHAR(30) CHARSET utf8, + pSecondName VARCHAR(30) CHARSET utf8, + pJobPositionID INT, + pDepartmentID INT, + pActivationCode VARCHAR(40) CHARSET utf8 +) RETURNS int(11) # 0 - success, <0 failed +NO SQL + BEGIN + DECLARE vAccountID INT DEFAULT -1; + DECLARE EXIT HANDLER FOR SQLEXCEPTION RETURN -1; + + SET vAccountID = CreateAccount(pActivationCode, GetUserRole('teacher')); + + # add new teacher + INSERT INTO teachers (AccountID, LastName, FirstName, SecondName, JobPositionID, DepartmentID) VALUES + (vAccountID, pLastName, pFirstName, pSecondName, pJobPositionID, pDepartmentID); + RETURN LAST_INSERT_ID(); + END // + +-- -1 - не Ñотрудник деканата и не преподаватель диÑциплины +-- 0 - только чтение +-- 1 - редактирование +DROP FUNCTION IF EXISTS GetEditRightsForTeacher// +CREATE FUNCTION GetEditRightsForTeacher ( + pTeacherID INT, + pDisciplineID INT +) RETURNS int(11) +NO SQL + BEGIN + DECLARE vUserRole INT DEFAULT -1; + + IF InternalIsTeacherBound(pTeacherID, pDisciplineID) > 0 THEN + RETURN 1; + END IF; + + SELECT accounts.UserRoleID INTO vUserRole + FROM teachers + INNER JOIN accounts ON teachers.AccountID = accounts.ID + WHERE teachers.ID = pTeacherID + LIMIT 1; + RETURN (vUserRole = GetUserRole('dean'), 0, -1); + END // + + + +# ------------------------------------------------------------------------------------------- +# Label: students +# ------------------------------------------------------------------------------------------- + + +DROP FUNCTION IF EXISTS CreateStudent// +CREATE FUNCTION CreateStudent ( + pLastName VARCHAR(30) CHARSET utf8, + pFirstName VARCHAR(30) CHARSET utf8, + pSecondName VARCHAR(30) CHARSET utf8, + pGroupID INT, + pActivationCode VARCHAR(40) CHARSET utf8, + pSemesterID INT +) RETURNS int(11) +NO SQL + BEGIN + DECLARE vAccountID, vStudentID INT DEFAULT -1; + DECLARE EXIT HANDLER FOR SQLEXCEPTION RETURN -1; + + SET vAccountID = CreateAccount(pActivationCode, GetUserRole('student')); + + # create student + INSERT INTO students (AccountID, LastName, FirstName, SecondName) + VALUES (vAccountID, pLastName, pFirstName, pSecondName); + SET vStudentID = LAST_INSERT_ID(); + + RETURN ControlStudentGroup(vStudentID, pGroupID, 'common', pSemesterID); + END // + +DROP FUNCTION IF EXISTS CreateStudentGroupSearch// +CREATE FUNCTION CreateStudentGroupSearch ( + pLastName VARCHAR(30) CHARSET utf8, + pFirstName VARCHAR(30) CHARSET utf8, + pSecondName VARCHAR(30) CHARSET utf8, + pGradeID INT, + pGroupNum INT, + pFacultyID INT, + pActivationCode VARCHAR(40) CHARSET utf8, + pSemesterID INT +) RETURNS int(11) +NO SQL + BEGIN + DECLARE vGroupID INT DEFAULT -1; + DECLARE EXIT HANDLER FOR SQLEXCEPTION RETURN -1; + + SET vGroupID = GetGroup(pGradeID, pGroupNum, pFacultyID); + IF vGroupID <= 0 THEN + RETURN -1; + END IF; + RETURN CreateStudent(pLastName, pFirstName, pSecondName, vGroupID, pActivationCode, pSemesterID); + END // + + +# unlike fn CreateStudent, this can create all missing records (group, grade, specialization) +DROP FUNCTION IF EXISTS CreateStudentEx// +CREATE FUNCTION CreateStudentEx ( + pLastName VARCHAR(30) CHARSET utf8, + pFirstName VARCHAR(30) CHARSET utf8, + pSecondName VARCHAR(30) CHARSET utf8, + pGradeNum INT, + pGroupNum INT, + pDegree enum('bachelor', 'master', 'specialist'), + pSpecName VARCHAR(50) CHARSET utf8, + pFacultyID INT, + pActivationCode VARCHAR(40) CHARSET utf8, + pSemesterID INT +) RETURNS int(11) +NO SQL + BEGIN + DECLARE vAccountID, vGradeID, vSpecID, vGroupID INT DEFAULT -1; + DECLARE EXIT HANDLER FOR SQLEXCEPTION RETURN -1; + + # get specialization id + INSERT INTO specializations (Name, Abbr, FacultyID) VALUES (pSpecName, NULL, pFacultyID) + ON DUPLICATE KEY UPDATE + specializations.ID = LAST_INSERT_ID(specializations.ID); + SET vSpecID = LAST_INSERT_ID(); + + SET vGradeID = CreateGrade(pGradeNum, pDegree); + SET vGroupID = CreateGroup(vGradeID, pGroupNum, vSpecID, NULL); + RETURN CreateStudent(pLastName, pFirstName, pSecondName, vGroupID, pActivationCode, pSemesterID); + END // + + + +# Give a student an academic leave or attach him to group. +# params: +# StudentID (int) +# GroupID (int) : -1, to update all appropriate 'common' records +# State (enum) +# SemesterID (int) +DROP FUNCTION IF EXISTS ControlStudentGroup// +CREATE FUNCTION ControlStudentGroup ( + pStudentID INT, + pGroupID INT, + pState enum('common', 'outlet', 'expulsion', 'leave'), + pSemesterID INT +) RETURNS int(11) +NO SQL + BEGIN + DECLARE vChecker INT DEFAULT 0; + DECLARE EXIT HANDLER FOR SQLEXCEPTION RETURN -1; + + INSERT INTO students_groups (StudentID, GroupID, SemesterID, State) + VALUES (pStudentID, pGroupID, pSemesterID, pState) + ON DUPLICATE KEY UPDATE + students_groups.GroupID = pGroupID, + students_groups.State = pState, + students_groups.Date = CURDATE(); + + RETURN ROW_COUNT()-1; + END // + +DROP FUNCTION IF EXISTS RemoveFromGroupInSemester// +CREATE FUNCTION RemoveFromGroupInSemester ( + pStudentID INT, + pGroupID INT, + pSemesterID INT +) RETURNS int(11) +NO SQL + BEGIN + DECLARE EXIT HANDLER FOR SQLEXCEPTION RETURN -1; + + DELETE FROM students_groups + WHERE students_groups.GroupID = pGroupID + and students_groups.StudentID = pStudentID + and students_groups.SemesterID = pSemesterID + and students_groups.State = 'common' + LIMIT 1; + RETURN ROW_COUNT()-1; + END // + + +# ------------------------------------------------------------------------------------------- +# Label: disciplines +# ------------------------------------------------------------------------------------------- + +DROP FUNCTION IF EXISTS GetDisciplineProperty// +CREATE FUNCTION GetDisciplineProperty ( + pDisciplineID INT, + pType enum('grade', 'subject', 'author', 'semester', 'milestone', 'type', 'maxrate') +) RETURNS int(11) +NO SQL + BEGIN + DECLARE vRes INT DEFAULT -1; + + SELECT CASE pType + WHEN 'semester' THEN disciplines.SemesterID + WHEN 'author' THEN disciplines.AuthorID + WHEN 'grade' THEN disciplines.GradeID + WHEN 'subject' THEN disciplines.SubjectID + WHEN 'milestone' THEN disciplines.Milestone + WHEN 'type' THEN disciplines.ExamType + 0 + WHEN 'maxrate' THEN disciplines.MaxRate + END INTO vRes + FROM disciplines + WHERE disciplines.ID = pDisciplineID + LIMIT 1; + + RETURN vRes; + END // + + +DROP FUNCTION IF EXISTS Discipline_Create// +CREATE FUNCTION Discipline_Create ( + pTeacherID INT, + pGradeID INT, + pSubjectID INT, + pExamType enum('exam', 'credit', 'grading_credit'), + pLectureCount INT, + pPracticeCount INT, + pLabCount INT, + pFacultyID INT, + pSemesterID INT, + pSubtype enum('scientific_coursework', 'disciplinary_coursework') +) RETURNS int(11) +NO SQL + BEGIN + DECLARE vDisciplineID INT DEFAULT -1; + DECLARE EXIT HANDLER FOR SQLEXCEPTION RETURN -1; + + # todo: make more flexible creation of coursework + # I mean, while creating scientific coursework + # we don't have the SubjectID field, but we must. + # 346 is used as a default id for scientific courseworks. + # This constant is duplicated in Model_Helper_CourseWorkBuilder + + IF pSubtype IS NOT NULL THEN + SET pSubjectID = 346; + END IF; + + # create discipline + INSERT INTO disciplines + ( AuthorID, GradeID, SubjectID, ExamType, LectureCount, PracticeCount,LabCount, SemesterID, FacultyID, Subtype) VALUES + (pTeacherID, pGradeID, pSubjectID, pExamType, pLectureCount, pPracticeCount, pLabCount, pSemesterID, pFacultyID, pSubtype); + SET vDisciplineID = LAST_INSERT_ID(); + + SELECT Discipline_BindTeacher(vDisciplineID, pTeacherID) INTO @vTemp; + + # add exam and extra modules + IF pExamType = 'exam' THEN + SELECT AddModuleExamUnsafe(vDisciplineID) INTO @vTemp; + END IF; + SELECT AddModuleExtra(pTeacherID, vDisciplineID) INTO @vTemp; + + RETURN vDisciplineID; + END // + + + + +DROP FUNCTION IF EXISTS ChangeDisciplineSubjectUnsafe// +CREATE FUNCTION ChangeDisciplineSubjectUnsafe ( + pDisciplineID INT, + pSubjectID INT +) RETURNS int(11) +NO SQL + BEGIN + DECLARE EXIT HANDLER FOR SQLEXCEPTION RETURN -1; + + UPDATE disciplines + SET disciplines.SubjectID = pSubjectID + WHERE disciplines.ID = pDisciplineID + LIMIT 1; + RETURN ROW_COUNT()-1; + END // + + +DROP FUNCTION IF EXISTS ChangeDisciplineSubject// +CREATE FUNCTION ChangeDisciplineSubject ( + pTeacherID INT, + pDisciplineID INT, + pSubjectID INT +) RETURNS int(11) +NO SQL + BEGIN + # TODO: move to php + IF NOT InternalIsTeacherAuthor(pTeacherID, pDisciplineID) OR + InternalIsMapLocked(pDisciplineID) + THEN + RETURN -1; + END IF; + RETURN ChangeDisciplineSubjectUnsafe(pDisciplineID, pSubjectID); + END // + + + +DROP FUNCTION IF EXISTS GetMilestone// +CREATE FUNCTION GetMilestone ( + pFacultyID INT, + pSemesterID INT +) RETURNS int(11) +NO SQL + BEGIN + DECLARE vMilestone, vCounter INT DEFAULT 0; + + # get most frequent milestone + SELECT COUNT(*) AS 'cnt', disciplines.Milestone INTO vCounter, vMilestone + FROM disciplines + WHERE disciplines.SemesterID = pSemesterID AND disciplines.FacultyID = pFacultyID + GROUP BY disciplines.Milestone + ORDER BY cnt DESC + LIMIT 1; + + RETURN vMilestone; + END // + +-- remove all students from discipline (separate bound & in general groups) +DROP FUNCTION IF EXISTS DeattachAllStudents// +CREATE FUNCTION DeattachAllStudents (pDisciplineID INT) RETURNS int(11) +NO SQL + BEGIN + DELETE FROM disciplines_groups + WHERE disciplines_groups.DisciplineID = pDisciplineID; + DELETE FROM disciplines_students + WHERE disciplines_students.DisciplineID = pDisciplineID; + RETURN 0; + END // + +DROP FUNCTION IF EXISTS ChangeDisciplineGradeUnsafe// +CREATE FUNCTION ChangeDisciplineGradeUnsafe ( + pDisciplineID INT, + pGradeID INT +) RETURNS int(11) +NO SQL + BEGIN + DECLARE EXIT HANDLER FOR SQLEXCEPTION RETURN -1; + + # TODO: move to php + IF InternalIsMapLocked(pDisciplineID) THEN + RETURN -1; + END IF; + IF GetDisciplineProperty(pDisciplineID, 'grade') <=> pGradeID THEN + RETURN 0; + END IF; + + SELECT DeattachAllStudents(pDisciplineID) INTO @vRes; + # set grade + UPDATE disciplines + SET disciplines.GradeID = pGradeID + WHERE disciplines.ID = pDisciplineID + LIMIT 1; + RETURN ROW_COUNT()-1; + END // + +DROP FUNCTION IF EXISTS ChangeDisciplineGrade// +CREATE FUNCTION ChangeDisciplineGrade ( + pTeacherID INT, + pDisciplineID INT, + pGradeID INT +) RETURNS int(11) +NO SQL + BEGIN + # TODO: move to php + IF NOT InternalIsTeacherAuthor(pTeacherID, pDisciplineID) THEN + RETURN -1; + END IF; + RETURN ChangeDisciplineGradeUnsafe(pDisciplineID, pGradeID); + END // + + +-- todo: check +DROP FUNCTION IF EXISTS ChangeDisciplineControl// +CREATE FUNCTION ChangeDisciplineControl ( + pTeacherID INT, + pDisciplineID INT, + pExamType enum('exam', 'credit', 'grading_credit') +) RETURNS int(11) +NO SQL + BEGIN + DECLARE vChecker, vExtraMax, vExtraID INT DEFAULT -1; + DECLARE vOldExamType enum('exam', 'credit', 'grading_credit'); + DECLARE EXIT HANDLER FOR SQLEXCEPTION RETURN -1; + + # todo: move to php + IF InternalIsMapLocked(pDisciplineID) OR NOT InternalIsTeacherAuthor(pTeacherID, pDisciplineID) THEN + RETURN -1; + END IF; + + # get exam type and extra module ID + SELECT disciplines.ExamType, modules.ID INTO vOldExamType, vExtraID + FROM modules + INNER JOIN disciplines ON disciplines.ID = modules.DisciplineID + WHERE modules.DisciplineID = pDisciplineID AND modules.Type = 'extra' + LIMIT 1; + IF vExtraID <= 0 THEN + RETURN -1; + END IF; + + # check type changing: exam <-> credit/grading_credit + IF NOT (vOldExamType = 'exam' XOR pExamType != 'exam') THEN + + # TODO: extract method addExtraModule + IF pExamType = 'exam' THEN # change to exam + # count discipline's current max rate + SET vChecker = GetDisciplineProperty(pDisciplineID, 'maxrate'); + IF vChecker >= 61 THEN # can't add exam module ( > 100 points) + RETURN 1; + END IF; + SET vChecker = AddModuleExamUnsafe(pDisciplineID); + + # delete extra submodules(only 1 extra for exam) + DELETE FROM submodules + WHERE submodules.OrderNum > 1 AND submodules.ModuleID = vExtraID; + + SET vExtraMax = 7; + ELSE # change to credit + SET vExtraMax = 29; + SET vChecker = DeleteModuleExam(pTeacherID, pDisciplineID); + # 2 extra submodules (1 already created for exam) + SET vChecker = AddSubmodule(pTeacherID, vExtraID, vExtraMax, '', NULL, 'LandmarkControl'); + END IF; + END IF; + + # set new exam type + UPDATE disciplines + SET disciplines.ExamType = pExamType + WHERE disciplines.ID = pDisciplineID + LIMIT 1; + + # set max rate for extra + UPDATE submodules + SET submodules.MaxRate = vExtraMax + WHERE submodules.ModuleID = vExtraID; + RETURN 0; + END // + +DROP FUNCTION IF EXISTS ChangeDisciplineHours// +CREATE FUNCTION ChangeDisciplineHours ( + pTeacherID INT, + pDisciplineID INT, + pHours INT, + pType INT + # Type: 0 - Practice Hours, 1 - Lecture Hours, 2 - Lab Hours +) RETURNS int(11) +NO SQL + BEGIN + IF NOT InternalIsTeacherAuthor(pTeacherID, pDisciplineID) THEN + RETURN -1; + END IF; + + CASE pType + WHEN 0 THEN + UPDATE disciplines + SET disciplines.PracticeCount = pHours + WHERE disciplines.ID = pDisciplineID + LIMIT 1; + WHEN 1 THEN + UPDATE disciplines + SET disciplines.LectureCount = pHours + WHERE disciplines.ID = pDisciplineID + LIMIT 1; + WHEN 2 THEN + UPDATE disciplines + SET disciplines.LabCount = pHours + WHERE disciplines.ID = pDisciplineID + LIMIT 1; + END CASE; + RETURN ROW_COUNT()-1; + END // + +DROP FUNCTION IF EXISTS LogBind// +CREATE FUNCTION LogBind ( + pDisciplineID INT, + pTeacherID INT, + EntityID INT, + pAttach enum('attach', 'detach'), + pType enum('group', 'student') +) RETURNS int(11) # 0 - success, < 0 - failed +NO SQL + BEGIN + DECLARE EXIT HANDLER FOR SQLEXCEPTION RETURN -1; + + IF pType = 'group' THEN + INSERT INTO logs_binds_groups + (DisciplineID, TeacherID, GroupID, Type) + VALUES (pDisciplineID, pTeacherID, EntityID, pAttach); + ELSEIF pType = 'student' THEN + INSERT INTO logs_binds_students + (DisciplineID, TeacherID, StudentID, Type) + VALUES (pDisciplineID, pTeacherID, EntityID, pAttach); + END IF; + RETURN ROW_COUNT()-1; + END // + + + +DROP FUNCTION IF EXISTS RemoveStudentsAttach// +CREATE FUNCTION RemoveStudentsAttach (pDisciplineID INT, pGroupID INT) RETURNS INT +NO SQL + BEGIN + DECLARE vSemesterID INT DEFAULT GetDisciplineProperty(pDisciplineID, 'semester'); + + DELETE FROM disciplines_students + WHERE disciplines_students.DisciplineID = pDisciplineID AND + disciplines_students.StudentID IN ( + SELECT students_groups.StudentID FROM students_groups + WHERE students_groups.GroupID = pGroupID AND students_groups.SemesterID = vSemesterID + ); + RETURN 0; + END // + +DROP FUNCTION IF EXISTS BindGroup// +CREATE FUNCTION BindGroup ( + pTeacherID INT, + pDisciplineID INT, + pGroupID INT +) RETURNS int(11) +NO SQL + BEGIN + DECLARE EXIT HANDLER FOR SQLEXCEPTION RETURN -3; + + # todo: move to php layer + IF NOT InternalIsTeacherBound(pTeacherID, pDisciplineID) OR InternalIsMapLocked(pDisciplineID) THEN + RETURN -1; + END IF; + + -- already bound + IF EXISTS( + SELECT * FROM disciplines_groups + WHERE disciplines_groups.DisciplineID = pDisciplineID AND disciplines_groups.GroupID = pGroupID + ) THEN + RETURN 1; + END IF; + + # bind whole group + INSERT INTO disciplines_groups (DisciplineID, GroupID) VALUES ( pDisciplineID, pGroupID ); + SELECT LogBind(pDisciplineID, pTeacherID, pGroupID, 'attach', 'group') INTO @vRes; + RETURN RemoveStudentsAttach(pDisciplineID, pGroupID); # delete students of this group which were bound to discipline before + END // + + +DROP FUNCTION IF EXISTS UnbindGroup// +CREATE FUNCTION UnbindGroup ( + pTeacherID INT, + pDisciplineID INT, + pGroupID INT +) RETURNS int(11) +NO SQL + BEGIN + # todo: move to php layer + IF NOT InternalIsTeacherBound(pTeacherID, pDisciplineID) OR InternalIsMapLocked(pDisciplineID) THEN + RETURN -1; + END IF; + + # detach group from the discipline + DELETE FROM disciplines_groups + WHERE disciplines_groups.DisciplineID = pDisciplineID AND disciplines_groups.GroupID = pGroupID + LIMIT 1; + + SELECT LogBind(pDisciplineID, pTeacherID, pGroupID, 'detach', 'group') INTO @vRes; + RETURN RemoveStudentsAttach(pDisciplineID, pGroupID); + END // + + + +DROP FUNCTION IF EXISTS BindStudent// +CREATE FUNCTION BindStudent ( + pTeacherID INT, + pDisciplineID INT, + pStudentID INT +) RETURNS int(11) +NO SQL + BEGIN + DECLARE vStudentGroupID, vSemesterID, vInGroup INT DEFAULT -1; + DECLARE EXIT HANDLER FOR SQLEXCEPTION RETURN -1; + + # todo: move to php layer + IF NOT InternalIsTeacherBound(pTeacherID, pDisciplineID) THEN + RETURN -1; + END IF; + + SET vSemesterID = GetDisciplineProperty(pDisciplineID, 'semester'); + SET vStudentGroupID = GetStudentGroup(pStudentID, vSemesterID); + + # check if student's group is bound yet + SET vInGroup = EXISTS( + SELECT * FROM disciplines_groups + WHERE disciplines_groups.DisciplineID = pDisciplineID AND disciplines_groups.GroupID = vStudentGroupID + LIMIT 1 + ); + + # bind student + IF vInGroup THEN # student in group -> try to remove detached attribute + DELETE FROM disciplines_students + WHERE disciplines_students.DisciplineID = pDisciplineID AND disciplines_students.StudentID = pStudentID + LIMIT 1; + ELSE # bind stand alone student ;( + INSERT INTO disciplines_students (DisciplineID, StudentID, Type) VALUES (pDisciplineID, pStudentID, 'attach') + ON DUPLICATE KEY UPDATE + disciplines_students.Type = 'attach'; + END IF; + + RETURN LogBind(pDisciplineID, pTeacherID, pStudentID, 'attach', 'student'); + END // + + + +DROP FUNCTION IF EXISTS UnbindStudent// +CREATE FUNCTION UnbindStudent ( + pTeacherID INT, + pDisciplineID INT, + pStudentID INT +) RETURNS int(11) +NO SQL + BEGIN + DECLARE vInGroup, vStudentGroupID, vSemesterID INT DEFAULT -1; + DECLARE EXIT HANDLER FOR SQLEXCEPTION RETURN -1; + + # todo: move to php layer + IF NOT InternalIsTeacherBound(pTeacherID, pDisciplineID) THEN + RETURN -1; + END IF; + + SET vSemesterID = GetDisciplineProperty(pDisciplineID, 'semester'); + SET vStudentGroupID = GetStudentGroup(pStudentID, vSemesterID); + + # 2. check if student's group is bound yet + SET vInGroup = EXISTS( + SELECT * FROM disciplines_groups + WHERE disciplines_groups.DisciplineID = pDisciplineID AND + disciplines_groups.GroupID = vStudentGroupID + LIMIT 1 + ); + + IF vInGroup > 0 THEN # student in general group + INSERT INTO disciplines_students (DisciplineID, StudentID, Type) VALUES (pDisciplineID, pStudentID, 'detach') + ON DUPLICATE KEY UPDATE disciplines_students.Type = 'detach'; + ELSE + DELETE FROM disciplines_students + WHERE disciplines_students.DisciplineID = pDisciplineID AND disciplines_students.StudentID = pStudentID + LIMIT 1; + END IF; + RETURN LogBind(pDisciplineID, pTeacherID, pStudentID, 'detach', 'student'); + END // + + + +DROP FUNCTION IF EXISTS Discipline_BindTeacher// +CREATE FUNCTION Discipline_BindTeacher ( + pDisciplineID INT, + pBindingTeacherID INT +) RETURNS int(11) +NO SQL + BEGIN + DECLARE EXIT HANDLER FOR SQLEXCEPTION RETURN -1; + + # try to insert BindingTeacher in access list + INSERT INTO disciplines_teachers (DisciplineID, TeacherID) VALUES (pDisciplineID, pBindingTeacherID) + ON DUPLICATE KEY UPDATE # just stub + disciplines_teachers.ID = LAST_INSERT_ID(disciplines_teachers.ID); + RETURN 0; + END // + + + +DROP FUNCTION IF EXISTS Discipline_UnbindTeacher// +CREATE FUNCTION Discipline_UnbindTeacher ( + pDisciplineID INT, + pBindingTeacher INT +) RETURNS int(11) +NO SQL + BEGIN + DELETE FROM disciplines_teachers + WHERE disciplines_teachers.DisciplineID = pDisciplineID AND disciplines_teachers.TeacherID = pBindingTeacher + LIMIT 1; + RETURN ROW_COUNT()-1; + END // + + +# assign new author to discipline +DROP FUNCTION IF EXISTS Discipline_Delegate// +CREATE FUNCTION Discipline_Delegate ( + pDisciplineID INT, + pNewAuthorID INT +) RETURNS int(11) +NO SQL + BEGIN + DECLARE EXIT HANDLER FOR SQLEXCEPTION RETURN -1; + + SELECT Discipline_BindTeacher(pDisciplineID, pNewAuthorID) INTO @vTemp; + UPDATE disciplines + SET disciplines.AuthorID = pNewAuthorID + WHERE disciplines.ID = pDisciplineID + LIMIT 1; + RETURN ROW_COUNT()-1; + END // + + +# erase all discipline's rates(and logs), unlock discipline for editing +DROP FUNCTION IF EXISTS ClearDiscipline// +CREATE FUNCTION ClearDiscipline ( + pAuthorTeacherID INT, + pDisciplineID INT +) RETURNS int(11) +NO SQL + BEGIN + IF NOT InternalIsTeacherAuthor(pAuthorTeacherID, pDisciplineID) THEN + RETURN -1; + END IF; + + # clear logs + DELETE FROM logs_rating + 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 + (SELECT view_roadmap.SubmoduleID + FROM view_roadmap + WHERE view_roadmap.DisciplineID = pDisciplineID); + + # unlock discipline + UPDATE disciplines + SET disciplines.IsLocked = 0 + WHERE disciplines.ID = pDisciplineID + LIMIT 1; + + RETURN ROW_COUNT()-1; + END // + + +DROP FUNCTION IF EXISTS Discipline_Delete// +CREATE FUNCTION Discipline_Delete (pDisciplineID INT) RETURNS int(11) +NO SQL + BEGIN + # delete roadmap + DELETE FROM submodules + WHERE submodules.moduleID in ( + select modules.id FROM modules + WHERE modules.DisciplineID = pDisciplineID + ); + + DELETE FROM modules + WHERE modules.DisciplineID = pDisciplineID; + + # detach all entities from discipline + DELETE FROM disciplines_teachers + WHERE disciplines_teachers.DisciplineID = pDisciplineID; + DELETE FROM disciplines_students + WHERE disciplines_students.DisciplineID = pDisciplineID; + DELETE FROM disciplines_groups + WHERE disciplines_groups.DisciplineID = pDisciplineID; + DELETE FROM logs_binds_groups + WHERE logs_binds_groups.DisciplineID = pDisciplineID; + DELETE FROM logs_binds_students + WHERE logs_binds_students.DisciplineID = pDisciplineID; + + # delete discipline + DELETE FROM disciplines + WHERE disciplines.ID = pDisciplineID + LIMIT 1; + + RETURN 0; + END // + + +# get count of related with discipline records in rating_table +DROP FUNCTION IF EXISTS Discipline_CountRatings// +CREATE FUNCTION Discipline_CountRatings (pDisciplineID INT) RETURNS int(11) +NO SQL + RETURN ( + SELECT COUNT(rating_table.StudentID) FROM view_roadmap + LEFT JOIN rating_table ON rating_table.SubmoduleID = view_roadmap.SubmoduleID + WHERE view_roadmap.DisciplineID = pDisciplineID + )// + + + +DROP FUNCTION IF EXISTS RestrictAfterMilestone// +CREATE FUNCTION RestrictAfterMilestone ( + pDisciplineID INT, + pMilestone INT +) RETURNS int(11) +NO SQL + BEGIN + UPDATE disciplines + SET disciplines.MilestoneDate = CURDATE(), + disciplines.Milestone = pMilestone + WHERE disciplines.ID = pDisciplineID + LIMIT 1; + RETURN 0; + END // + + +DROP FUNCTION IF EXISTS RestrictAfterMilestoneForCredits// +CREATE FUNCTION RestrictAfterMilestoneForCredits ( + pFacultyID INT, + pMilestone INT, + pSemesterID INT +) RETURNS int(11) +NO SQL + BEGIN + UPDATE disciplines + SET disciplines.MilestoneDate = CURDATE(), + disciplines.Milestone = pMilestone + WHERE disciplines.FacultyID= pFacultyID AND + disciplines.SemesterID = pSemesterID AND + ( disciplines.ExamType = 'credit' OR disciplines.ExamType = 'grading_credit'); + RETURN 0; + END // + + + +# ------------------------------------------------------------------------------------------- +# Label: modules +# Label: roadmap +# ------------------------------------------------------------------------------------------- + +DROP FUNCTION IF EXISTS ChangeModuleName// +CREATE FUNCTION ChangeModuleName ( + pTeacherID INT, + pModuleID INT, + pName VARCHAR(200) CHARSET utf8 +) RETURNS int(11) +NO SQL + BEGIN + DECLARE vDisciplineID INT DEFAULT -1; + DECLARE vAlreadySameName BOOL DEFAULT FALSE; + + SET vDisciplineID = (SELECT DisciplineID FROM modules WHERE ID = pModuleID LIMIT 1); + IF InternalIsMapLocked(vDisciplineID) THEN + RETURN -1; + END IF; + + # Bodging, strange row_count() behaviour in some cases. + # i.e. update 1 module row. In case it's new and old names are same, row_count value may be 0. + SET vAlreadySameName = EXISTS( + SELECT * FROM modules + WHERE modules.ID = pModuleID AND modules.Type = 'regular' AND modules.Name = pName + LIMIT 1 + ); + IF vAlreadySameName THEN + return 0; + END IF; + + + UPDATE modules + SET modules.Name = pName + WHERE modules.ID = pModuleID AND modules.Type = 'regular' + LIMIT 1; + RETURN ROW_COUNT() - 1; + END // + + + +DROP FUNCTION IF EXISTS AddModule// +CREATE FUNCTION AddModule ( + pTeacherID INT, + pDisciplineID INT, + pName VARCHAR(200) CHARSET utf8 +) RETURNS int(11) +NO SQL + BEGIN + DECLARE vOrderNum INT DEFAULT 0; + DECLARE EXIT HANDLER FOR SQLEXCEPTION RETURN -1; + + IF NOT InternalIsTeacherAuthor(pTeacherID, pDisciplineID) OR InternalIsMapLocked(pDisciplineID) THEN + RETURN -2; + END IF; + + # get free orderNum + SET vOrderNum = COALESCE(( + SELECT MAX(modules.OrderNum)+1 FROM modules + WHERE modules.DisciplineID = pDisciplineID AND modules.Type = 'regular' LIMIT 1 + ), 1); + + INSERT INTO modules (Name, OrderNum, DisciplineID ) VALUES (pName, vOrderNum, pDisciplineID); + RETURN LAST_INSERT_ID(); + END // + + + +DROP FUNCTION IF EXISTS AddModuleExamUnsafe// +CREATE FUNCTION AddModuleExamUnsafe (pDisciplineID INT) RETURNS int(11) +NO SQL + BEGIN + DECLARE vModule, vChecker INT DEFAULT -1; + DECLARE vIsExamExists BOOLEAN; + + IF InternalIsMapLocked(pDisciplineID) THEN + RETURN -1; + END IF; + + SET vIsExamExists = EXISTS( + SELECT * FROM modules + WHERE modules.DisciplineID = pDisciplineID AND modules.Type = 'exam' + LIMIT 1 + ); + IF vIsExamExists THEN + RETURN -2; + END IF; + + INSERT INTO modules (Name, OrderNum, DisciplineID, Type) VALUES ('Ðкзамен' , 3141592 , pDisciplineID, 'exam'); + SET vModule = LAST_INSERT_ID(); + # 3 attempt for pass exam + SELECT AddSubmoduleUnsafe(vModule, 40, '', NULL, 'LandmarkControl') INTO @vTemp; + SELECT AddSubmoduleUnsafe(vModule, 40, '', NULL, 'LandmarkControl') INTO @vTemp; + SELECT AddSubmoduleUnsafe(vModule, 40, '', NULL, 'LandmarkControl') INTO @vTemp; + RETURN vModule; + END // + + +DROP FUNCTION IF EXISTS AddModuleExam// +CREATE FUNCTION AddModuleExam ( + pTeacherID INT, + pDisciplineID INT +) RETURNS int(11) +NO SQL + BEGIN + DECLARE vModule, vChecker INT DEFAULT -1; + DECLARE vIsExamExists BOOLEAN; + IF NOT InternalIsTeacherAuthor(pTeacherID, pDisciplineID) OR + InternalIsMapLocked(pDisciplineID) + THEN + RETURN -1; + END IF; + + RETURN AddModuleExamUnsafe(pDisciplineID); + END // + + +DROP FUNCTION IF EXISTS AddModuleExtra// +CREATE FUNCTION AddModuleExtra ( + pTeacherID INT, + pDisciplineID INT +) RETURNS int(11) +NO SQL + BEGIN + DECLARE vChecker, vModule, vType, vGap INT DEFAULT -1; + DECLARE EXIT HANDLER FOR SQLEXCEPTION RETURN -1; + IF NOT InternalIsTeacherAuthor(pTeacherID, pDisciplineID) + THEN + RETURN -1; + END IF; + + # try to find existing extra module + SELECT modules.ID INTO vChecker + FROM modules + WHERE modules.DisciplineID = pDisciplineID AND modules.Type = 'extra' + LIMIT 1; + IF vChecker > 0 THEN + RETURN -2; + END IF; + + # add extra module + INSERT INTO modules + (Name, OrderNum, DisciplineID, Type) + VALUES ('Добор баллов' , 2900666 , pDisciplineID, 'extra'); + + + # get discipline exam type + SELECT modules.ID, disciplines.ExamType INTO vModule, vType + FROM modules + INNER JOIN disciplines ON disciplines.ID = modules.DisciplineID + WHERE modules.DisciplineID = pDisciplineID AND + modules.Type = 'extra' + LIMIT 1; + IF vModule <= 0 THEN + RETURN -1; + END IF; + + # 1 extra attempt for exam and 2 for credit + SET vGap = -1; + IF vType = 1 THEN # exam + SET vGap = 7; + END IF; + IF vType = 2 OR vType = 3 THEN # credit, grading_credit + SET vGap = 29; + SET vChecker = AddSubmodule(pTeacherID, vModule, vGap, '', NULL, 'LandmarkControl'); + END IF; + + SET vChecker = AddSubmodule(pTeacherID, vModule, vGap, '', NULL, 'LandmarkControl'); + RETURN vModule; + END // + + +DROP FUNCTION IF EXISTS DeleteModule// +CREATE FUNCTION DeleteModule ( + pTeacherID INT, + pModuleID INT +) RETURNS int(11) +NO SQL + BEGIN + DECLARE vDisciplineID INT DEFAULT -1; + + # get discipline ID + SET vDisciplineID = ( + SELECT disciplines.ID FROM modules + INNER JOIN disciplines ON modules.DisciplineID = disciplines.ID AND disciplines.AuthorID = pTeacherID + WHERE modules.ID = pModuleID LIMIT 1 + ); + + # check rights + IF NOT InternalIsTeacherAuthor(pTeacherID, vDisciplineID) OR + InternalIsMapLocked(vDisciplineID) + THEN + RETURN -1; + END IF; + + DELETE FROM submodules + WHERE submodules.ModuleID = pModuleID; + DELETE FROM modules + WHERE modules.ID = pModuleID; + + # restore continuous ordering + SET @counter = 0; + UPDATE modules + SET modules.OrderNum = (@counter := @counter + 1) + WHERE modules.DisciplineID = vDisciplineID AND + modules.Type = 'regular' + ORDER BY modules.OrderNum ASC; + + RETURN 0; + END // + + + +DROP FUNCTION IF EXISTS DeleteModuleExam// +CREATE FUNCTION DeleteModuleExam ( + pTeacherID INT, + pDisciplineID INT +) RETURNS int(11) +NO SQL + BEGIN + DECLARE vExamModuleID INT DEFAULT -1; + IF NOT InternalIsTeacherAuthor(pTeacherID, pDisciplineID) OR + InternalIsMapLocked(pDisciplineID) + THEN + RETURN -1; + END IF; + + # get exam module ID + SELECT modules.ID INTO vExamModuleID + FROM modules + WHERE modules.Type = 'exam' AND + modules.DisciplineID = pDisciplineID + LIMIT 1; + IF vExamModuleID <= 0 THEN + RETURN -1; + END IF; + + DELETE FROM submodules + WHERE vExamModuleID = submodules.ModuleID; + DELETE FROM modules + WHERE vExamModuleID = modules.ID + LIMIT 1; + + RETURN 0; + END // + + + +DROP FUNCTION IF EXISTS SwapModuleOrder// +CREATE FUNCTION SwapModuleOrder ( + pTeacherID INT, + pModuleID1 INT, + pModuleID2 INT +) RETURNS int(11) +NO SQL + BEGIN + DECLARE vChecker, vOrder1, vOrder2, + vDisciplineID1, vDisciplineID2 INT DEFAULT -1; + + # get disciplineID and orderNum for 1st module(pModuleID1) + SELECT modules.OrderNum, + modules.DisciplineID + INTO vOrder1, vDisciplineID1 + FROM modules + INNER JOIN disciplines ON disciplines.ID = modules.DisciplineID + WHERE disciplines.AuthorID = pTeacherID AND + modules.ID = pModuleID1 AND + modules.Type = 'regular' + LIMIT 1; + + # get disciplineID and orderNum for 2st module(pModuleID2) + SELECT modules.OrderNum, + modules.DisciplineID + INTO vOrder2, vDisciplineID2 + FROM modules + INNER JOIN disciplines ON disciplines.ID = modules.DisciplineID + WHERE disciplines.AuthorID = pTeacherID AND + modules.ID = pModuleID2 AND + modules.Type = 'regular' + LIMIT 1; + + # check that modules belong to one discipline, check rights + IF vDisciplineID1 != vDisciplineID2 OR vDisciplineID1 <= 0 OR + InternalIsMapLocked(vDisciplineID1) THEN + RETURN -1; + END IF; + + # swap + UPDATE modules + SET modules.OrderNum = 271828 + WHERE modules.ID = pModuleID1; + UPDATE modules + SET modules.OrderNum = vOrder1 + WHERE modules.ID = pModuleID2 + LIMIT 1; + UPDATE modules + SET modules.OrderNum = vOrder2 + WHERE modules.ID = pModuleID1 + LIMIT 1; + + RETURN 0; + END // + + + +DROP FUNCTION IF EXISTS AddModuleBonus// +CREATE FUNCTION AddModuleBonus ( + pTeacherID INT, + pDisciplineID INT +) RETURNS INT(11) +NO SQL + BEGIN + DECLARE vChecker, vModuleID INT DEFAULT -1; + IF NOT InternalIsTeacherAuthor(pTeacherID, pDisciplineID) OR + InternalIsMapLocked(pDisciplineID) + THEN + RETURN -1; + END IF; + + # check existing of bonus module + SELECT modules.ID INTO vChecker + FROM modules + WHERE modules.DisciplineID = pDisciplineID AND + modules.Type = 'bonus'; + IF vChecker > 0 THEN + RETURN -2; + END IF; + + INSERT INTO modules + (Name, OrderNum, DisciplineID, Type) + VALUES ('БонуÑные баллы' , 2141692 , pDisciplineID, 'bonus'); + + SET vModuleID = LAST_INSERT_ID(); + SET vChecker = AddSubmodule(pTeacherID, vModuleID, 10, '', NULL, 'LandmarkControl'); + RETURN 0; + END // + + +DROP FUNCTION IF EXISTS GetBonusModule// +CREATE FUNCTION GetBonusModule (pDisciplineID INT) RETURNS int(11) +NO SQL + RETURN ( + SELECT modules.ID FROM modules + WHERE modules.DisciplineID = pDisciplineID AND modules.Type = 'bonus' + LIMIT 1 + )// + +DROP FUNCTION IF EXISTS DeleteModuleBonus// +CREATE FUNCTION DeleteModuleBonus ( + pTeacherID INT, + pDisciplineID INT +) RETURNS int(11) +NO SQL + BEGIN + DECLARE vBonusModuleID INT DEFAULT -1; + IF NOT InternalIsTeacherAuthor(pTeacherID, pDisciplineID) OR + InternalIsMapLocked(pDisciplineID) + THEN + RETURN -1; + END IF; + IF GetBonusModule(pDisciplineID) <= 0 THEN + RETURN -1; + END IF; + + DELETE FROM submodules + WHERE vBonusModuleID = submodules.ModuleID; + + DELETE FROM modules + WHERE vBonusModuleID = modules.ID + LIMIT 1; + + RETURN 0; + END // + + + +# ------------------------------------------------------------------------------------------- +# Label: submodules +# Label: roadmap +# ------------------------------------------------------------------------------------------- + +DROP FUNCTION IF EXISTS ChangeSubmoduleMaxAndControl// +CREATE FUNCTION ChangeSubmoduleMaxAndControl ( + pTeacherID INT, + pSubmoduleID INT, + pMaxRate INT, + pControlType VARCHAR(30) CHARSET utf8 +) RETURNS int(11) +NO SQL + BEGIN + DECLARE vChecker, vDisciplineID, vIsLocked, vNewDiscMaxRate, vCurRate INT DEFAULT -1; + + # check that discipline and submodule exists and doesn't locked + SELECT disciplines.IsLocked, + 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 + WHERE submodules.ID = pSubmoduleID AND + disciplines.AuthorID = pTeacherID + LIMIT 1; + IF vIsLocked != 0 OR + vNewDiscMaxRate > 100 + THEN + RETURN -1; + END IF; + + UPDATE submodules + SET submodules.MaxRate = pMaxRate, + submodules.Type = pControlType + WHERE submodules.ID = pSubmoduleID + LIMIT 1; + RETURN ROW_COUNT()-1; + END // + + + +DROP FUNCTION IF EXISTS ChangeSubmoduleName// +CREATE FUNCTION ChangeSubmoduleName ( + pTeacherID INT, + pSubmoduleID INT, + pName VARCHAR(200) CHARSET utf8 +) RETURNS int(11) +NO SQL + BEGIN + DECLARE vIsLocked INT DEFAULT -1; + + SELECT disciplines.IsLocked INTO vIsLocked + FROM view_roadmap + INNER JOIN disciplines ON disciplines.ID = view_roadmap.DisciplineID + WHERE view_roadmap.SubmoduleID = pSubmoduleID AND disciplines.AuthorID = pTeacherID + LIMIT 1; + IF vIsLocked != 0 THEN + RETURN -1; + END IF; + + UPDATE submodules + SET submodules.Name = pName + WHERE submodules.ID = pSubmoduleID + LIMIT 1; + RETURN 0; + END // + + + +DROP FUNCTION IF EXISTS ChangeSubmoduleDescription// +CREATE FUNCTION ChangeSubmoduleDescription ( + pTeacherID INT, + pSubmoduleID INT, + pDescription VARCHAR(200) CHARSET utf8 +) RETURNS int(11) +NO SQL + BEGIN + DECLARE vIsLocked INT DEFAULT -1; + + SELECT disciplines.IsLocked INTO vIsLocked + FROM view_roadmap + INNER JOIN disciplines ON disciplines.ID = view_roadmap.DisciplineID + WHERE view_roadmap.SubmoduleID = pSubmoduleID AND disciplines.AuthorID = pTeacherID + LIMIT 1; + IF vIsLocked != 0 THEN + RETURN -1; + END IF; + + UPDATE submodules + SET submodules.Description = pDescription + WHERE submodules.ID = pSubmoduleID + LIMIT 1; + RETURN 0; + END // + + + + +DROP FUNCTION IF EXISTS DeleteSubmodule// +CREATE FUNCTION DeleteSubmodule ( + pTeacherID INT, + pSubmoduleID INT +) RETURNS int(11) +NO SQL + BEGIN + DECLARE vIsLocked, vModuleID INT DEFAULT -1; + DECLARE EXIT HANDLER FOR SQLEXCEPTION RETURN -1; + + SELECT modules.ID, disciplines.IsLocked + INTO vModuleID, vIsLocked + FROM submodules + INNER JOIN modules ON modules.ID = submodules.ModuleID + INNER JOIN disciplines ON modules.DisciplineID = disciplines.ID + WHERE disciplines.AuthorID = pTeacherID AND + submodules.ID = pSubmoduleID + LIMIT 1; + IF vIsLocked != 0 THEN + RETURN -1; + END IF; + + # handler will catch constraint violation + DELETE FROM submodules + WHERE submodules.ID = pSubmoduleID + LIMIT 1; + + # restore continuous ordering + SET @counter = 0; + UPDATE submodules + SET submodules.OrderNum = (@counter := @counter + 1) + WHERE submodules.ModuleID = vModuleID + ORDER BY submodules.OrderNum ASC; + + RETURN 0; + END // + + +DROP FUNCTION IF EXISTS AddSubmoduleUnsafe// +CREATE FUNCTION AddSubmoduleUnsafe ( + pModuleID INT, + pMaxRate INT, + pName VARCHAR(200) CHARSET utf8, + pDescription VARCHAR(200) CHARSET utf8, + pControlType VARCHAR(30) CHARSET utf8 +) RETURNS int(11) +NO SQL + BEGIN + DECLARE vOrderNum, vIsLocked INT DEFAULT -1; + DECLARE vDescription VARCHAR(200) CHARSET utf8 DEFAULT NULL; + # DECLARE EXIT HANDLER FOR SQLEXCEPTION RETURN -1; + + # check discipline lock + SELECT disciplines.IsLocked INTO vIsLocked + FROM modules + INNER JOIN disciplines ON disciplines.ID = modules.DisciplineID + WHERE modules.ID = pModuleID + LIMIT 1; + IF vIsLocked != 0 THEN + RETURN -2; + END IF; + + # get free order + SET vOrderNum = COALESCE(( + SELECT MAX(submodules.OrderNum) FROM submodules + WHERE submodules.ModuleID = pModuleID LIMIT 1 + ), 0) + 1; + + SET vDescription = IF(vDescription = '', NULL, pDescription); + INSERT INTO submodules (ModuleID, MaxRate, OrderNum, Name, Description, Type) VALUES + (pModuleID, pMaxRate, vOrderNum, pName, vDescription, pControlType); + RETURN LAST_INSERT_ID(); + END // + + + +DROP FUNCTION IF EXISTS AddSubmodule// +CREATE FUNCTION AddSubmodule ( + pTeacherID INT, + pModuleID INT, + pMaxRate INT, + pName VARCHAR(200) CHARSET utf8, + pDescription VARCHAR(200) CHARSET utf8, + pControlType VARCHAR(30) CHARSET utf8 +) RETURNS int(11) +NO SQL + BEGIN + DECLARE vIsLocked BOOLEAN DEFAULT TRUE; + # DECLARE EXIT HANDLER FOR SQLEXCEPTION RETURN -1; + + # check author and discipline lock + SELECT NOT disciplines.AuthorID <=> pTeacherID INTO vIsLocked + FROM modules + INNER JOIN disciplines ON disciplines.ID = modules.DisciplineID + WHERE modules.ID = pModuleID + LIMIT 1; + IF vIsLocked THEN + RETURN -2; + END IF; + + RETURN AddSubmoduleUnsafe(pModuleID, pMaxRate, pName, pDescription, pControlType); + END // + + + +DROP FUNCTION IF EXISTS SwapSubmoduleOrder// +CREATE FUNCTION SwapSubmoduleOrder ( + pTeacherID INT, + pSubmoduleID1 INT, + pSubmoduleID2 INT +) RETURNS int(11) +NO SQL + BEGIN + DECLARE vDisciplineID, vOrder1, vOrder2, + vModule1, vModule2 INT DEFAULT -1; + + SELECT submodules.OrderNum, + submodules.ModuleID, + disciplines.ID + INTO vOrder1, vModule1, vDisciplineID + FROM submodules + INNER JOIN modules ON submodules.ModuleID = modules.ID + INNER JOIN disciplines ON disciplines.ID = modules.DisciplineID + WHERE disciplines.AuthorID = pTeacherID AND + submodules.ID = pSubmoduleID1 + LIMIT 1; + + SELECT submodules.OrderNum, + submodules.ModuleID + INTO vOrder2, vModule2 + FROM submodules + INNER JOIN modules ON submodules.ModuleID = modules.ID + INNER JOIN disciplines ON disciplines.ID = modules.DisciplineID + WHERE disciplines.AuthorID = pTeacherID AND + submodules.ID = pSubmoduleID2 + LIMIT 1; + + # check, that modules exists and belong to one discipline + IF vModule1 <= 0 OR vModule1 != vModule2 OR + InternalIsMapLocked(vDisciplineID) + THEN + RETURN -1; + END IF; + + # swap + UPDATE submodules + SET submodules.OrderNum = 271828 + WHERE submodules.ID = pSubmoduleID1 + LIMIT 1; + UPDATE submodules + SET submodules.OrderNum = vOrder1 + WHERE submodules.ID = pSubmoduleID2 + LIMIT 1; + UPDATE submodules + SET submodules.OrderNum = vOrder2 + WHERE submodules.ID = pSubmoduleID1 + LIMIT 1; + RETURN 0; + END // + + +# ------------------------------------------------------------------------------------------- +# Label: rating +# ------------------------------------------------------------------------------------------- + +-- get id of student's last exam with rate +-- first exam submodule, if don't rated yet +DROP FUNCTION IF EXISTS GetExamRateID// +CREATE FUNCTION GetExamRateID ( + pStudentID INT, + pDisciplineID INT +) RETURNS int(11) +NO SQL + RETURN COALESCE(( + SELECT view_roadmap.SubmoduleID FROM view_roadmap + LEFT JOIN rating_table AS rt on rt.SubmoduleID = view_roadmap.SubmoduleID AND rt.StudentID = pStudentID + WHERE view_roadmap.DisciplineID = pDisciplineID AND view_roadmap.ModuleType = 'exam' + ORDER BY (rt.Rate IS NOT NULL) DESC, view_roadmap.SubmoduleOrderNum DESC + LIMIT 1 + ), -1)// + +# ВычиÑление макÑимального балла Ð´Ð»Ñ submodule +DROP FUNCTION IF EXISTS CalculateMaxRateForExtra// +CREATE FUNCTION CalculateMaxRateForExtra ( + pDisciplineID INT, + pStudentID INT +) RETURNS int(11) +NO SQL + BEGIN + DECLARE vExamType enum('exam', 'credit', 'grading_credit') DEFAULT NULL; + DECLARE vDiscID, vLim, vResult INT DEFAULT 0; + + # get disc type + SET vExamType = GetDisciplineProperty(pDisciplineID, 'type'); + + # submodule doesn't exists + IF vExamType IS NULL OR vExamType <= 0 THEN + RETURN -1; + END IF; + SET vLim = IF(vExamType = 'exam', 38, 60); + + SELECT SUM(IF(view_roadmap.ModuleType = 'regular', rating_table.Rate, 0)) INTO vResult + FROM view_roadmap + LEFT JOIN rating_table ON rating_table.StudentID = pStudentID AND + rating_table.SubmoduleID = view_roadmap.SubmoduleID + WHERE view_roadmap.DisciplineID = pDisciplineID + LIMIT 1; + RETURN vLim - vResult; + END // + + +DROP FUNCTION IF EXISTS SetStudentRate// +CREATE FUNCTION SetStudentRate ( + pTeacherID INT, + pStudentID INT, + pSubmoduleID INT, + pRate INT +) RETURNS int(11) +NO SQL + BEGIN + DECLARE vDisciplineID, vMaxRate, vModuleType INT DEFAULT -1; + DECLARE vIsOver, vIsLocked, vIsUsed BOOLEAN DEFAULT FALSE; + DECLARE EXIT HANDLER FOR SQLEXCEPTION RETURN -1; + + IF pRate < 0 THEN + INSERT INTO logs_rating (StudentID, SubmoduleID, TeacherID, Rate, Action ) VALUES + (pStudentID, pSubmoduleID, pTeacherID, pRate, 'delete'); + + # TODO: extract method log rate + DELETE FROM rating_table + WHERE rating_table.StudentID = pStudentID AND + rating_table.SubmoduleID = pSubmoduleID + LIMIT 1; + + RETURN ROW_COUNT()-1; + END IF; + + SET vIsOver = TRUE; + SELECT disciplines.ID, + disciplines.IsLocked, + disciplines.Milestone, + submodules.IsUsed, + submodules.maxRate, + modules.Type + INTO vDisciplineID, vIsLocked, vIsOver, vIsUsed, vMaxRate, vModuleType + FROM submodules + INNER JOIN modules ON submodules.ModuleID = modules.ID + INNER JOIN disciplines ON modules.DisciplineID = disciplines.ID + WHERE submodules.ID = pSubmoduleID + LIMIT 1; + + # correct max rate for extra module + IF vModuleType = 4 THEN # 4 - extra + SET vMaxRate = CalculateMaxRateForExtra(vDisciplineID, pStudentID); + END IF; + + # 1) check rights + # 2) check, you can't rate regular and bonus after milestone + # 3) check, max rate exceeding + IF NOT InternalIsStudentAttached(pStudentID, vDisciplineID) OR + NOT InternalIsTeacherBound(pTeacherID, vDisciplineID) OR + pRate > vMaxRate OR + (vIsOver AND (vModuleType = 1 OR vModuleType = 3)) # 1 - regular, 3 - bonus + THEN + RETURN -2; + END IF; + + # add rate, or update old + SET @tmp = 0; + INSERT INTO rating_table (StudentID, TeacherID, SubmoduleID, Rate, Date) + VALUES ( pStudentID, pTeacherID, pSubmoduleID, pRate, CURDATE() ) + ON DUPLICATE KEY UPDATE + rating_table.TeacherID = (@tmp := pTeacherID), + rating_table.Rate = pRate, + rating_table.Date = CURDATE(); + + # log rate + INSERT INTO logs_rating (StudentID, SubmoduleID, TeacherID, Rate, Action ) + VALUES (pStudentID, pSubmoduleID, pTeacherID, pRate, IF(@tmp > 0, 'add', 'change') ); + + # lock discipline for structure editing + IF NOT vIsLocked THEN + UPDATE disciplines + SET disciplines.IsLocked = TRUE + WHERE disciplines.ID = vDisciplineID + LIMIT 1; + END IF; + + # add submodule to max rate counting (see triggers) + IF NOT vIsUsed THEN + UPDATE submodules + SET submodules.IsUsed = TRUE + WHERE submodules.ID = pSubmoduleID + LIMIT 1; + END IF; + RETURN 0; + END // + + + + + +# ------------------------------------------------------------------------------------------- +# Label: requests +# ------------------------------------------------------------------------------------------- + + + +DROP FUNCTION IF EXISTS SetRequestStatus// +CREATE FUNCTION SetRequestStatus ( + pRequestID INT, + pStatus enum('opened','processed','closed') +) RETURNS int(11) +NO SQL + BEGIN + DECLARE EXIT HANDLER FOR SQLEXCEPTION RETURN -1; + UPDATE requests + SET requests.Status = pStatus + WHERE requests.ID = pRequestID + LIMIT 1; + RETURN ROW_COUNT()-1; + END// + +-- todo: does it work? HasImage field not found +DROP FUNCTION IF EXISTS CreateRequest// +CREATE FUNCTION CreateRequest ( + pAccountID INT, + pTitle VARCHAR(50) CHARSET utf8, + pDescription TEXT CHARSET utf8, + pImage BOOLEAN +) RETURNS int(11) +NO SQL + BEGIN + DECLARE EXIT HANDLER FOR SQLEXCEPTION RETURN -1; + + INSERT INTO requests + (AccountID, Title, Description, Status, HasImage) + VALUES (pAccountID, pTitle, pDescription, 'opened', pImage); + RETURN LAST_INSERT_ID(); + END// + +DROP FUNCTION IF EXISTS UpdateRequest// +CREATE FUNCTION UpdateRequest ( + pRequestID INT, + pTitle VARCHAR(50) CHARSET utf8, + pDescription TEXT CHARSET utf8 +) RETURNS int(11) +NO SQL + BEGIN + DECLARE EXIT HANDLER FOR SQLEXCEPTION RETURN -1; + + UPDATE requests + SET requests.Description = pDescription, + requests.Title = pTitle, + requests.Date = NOW() + WHERE requests.ID = pRequestID AND + requests.Description IS NULL AND + requests.Title IS NULL + LIMIT 1; + RETURN ROW_COUNT()-1; + END// + +# return StudentID or TeacherID depending on UserRoleID +DROP FUNCTION IF EXISTS GetUserStudentOrTeacherID// +CREATE FUNCTION GetUserStudentOrTeacherID ( + pAccountID INT(11), + pUserRoleID INT(11) +) RETURNS INT(11) + BEGIN + DECLARE vID INT DEFAULT -1; + + IF pUserRoleID = GetUserRole('student') THEN + SELECT students.ID + INTO vID + FROM students + WHERE students.AccountID = pAccountID + LIMIT 1; + ELSE + SELECT teachers.ID + INTO vID + FROM teachers + WHERE teachers.AccountID = pAccountID + LIMIT 1; + END IF; + + RETURN vID; + END// + + + +# ------------------------------------------------------------------------------------------- +# Label: recovery +# ------------------------------------------------------------------------------------------- + + + +DROP FUNCTION IF EXISTS CreateRecoveryToken// +CREATE FUNCTION CreateRecoveryToken ( + pAccountOrEMail VARCHAR(255) CHARSET utf8, + pToken VARCHAR(100) CHARSET utf8 +) RETURNS VARCHAR(255) charset utf8 +NO SQL + BEGIN + DECLARE vAccountID INT DEFAULT -1; + DECLARE vUserFullName TEXT charset utf8; + DECLARE EXIT HANDLER FOR SQLEXCEPTION RETURN -2; + + # get account ID + SELECT accounts.ID INTO vAccountID + FROM accounts + WHERE accounts.EMail = pAccountOrEMail OR + accounts.Login = pAccountOrEMail + LIMIT 1; + IF vAccountID <= 0 THEN + RETURN ''; + END IF; + + SET vUserFullName = GetUserFullNameByAccountID(vAccountID); + IF vUserFullName IS NULL OR vUserFullName = '' THEN + RETURN ''; + END IF; + + # transform all unused recovery tokens into used + UPDATE recovery_tokens + SET recovery_tokens.isUsed = 1 + WHERE recovery_tokens.isUsed = 0 AND + recovery_tokens.AccountID = vAccountID; + + # handle catch constraints violations + INSERT INTO recovery_tokens + ( AccountID, Token ) + VALUES (vAccountID, pToken); + RETURN vUserFullName; + END// + +DROP FUNCTION IF EXISTS GetUserFullNameByAccountID// +CREATE FUNCTION GetUserFullNameByAccountID ( + pAccountID INT(11) +) RETURNS VARCHAR(255) charset utf8 +NO SQL + BEGIN + DECLARE vUserFullName VARCHAR(255) charset utf8; + DECLARE vChecker INT DEFAULT -1; + + # try to find student with that account id + SELECT students.ID, CONCAT(students.LastName,' ',students.FirstName,' ',students.SecondName) + INTO vChecker, vUserFullName + FROM students + WHERE students.AccountID = pAccountID + LIMIT 1; + + IF vChecker <= 0 THEN # try to find teacher with that account id + SELECT teachers.ID, CONCAT(teachers.LastName,' ',teachers.FirstName,' ',teachers.SecondName) + INTO vChecker, vUserFullName + FROM teachers + WHERE teachers.AccountID = pAccountID + LIMIT 1; + + IF vChecker <= 0 THEN + RETURN ''; + END IF; + END IF; + + RETURN vUserFullName; + END// + +DROP FUNCTION IF EXISTS UseRecoveryToken// +CREATE FUNCTION UseRecoveryToken ( + pToken VARCHAR(100) CHARSET utf8 +) RETURNS int(11) +NO SQL + BEGIN + DECLARE vChecker INT DEFAULT -1; + + # set token used + UPDATE recovery_tokens + SET recovery_tokens.IsUsed = 1 + WHERE recovery_tokens.Token = pToken + LIMIT 1; + RETURN ROW_COUNT()-1; + END// + +DELIMITER ; -- GitLab