diff --git a/db/StoredFunctions.sql b/db/StoredFunctions.sql index e3c8d82438164684c94fd2aa0c27feaea8920a55..f3c1503736dc82de37a87c64b9f348b9bdda1d84 100644 --- a/db/StoredFunctions.sql +++ b/db/StoredFunctions.sql @@ -28,6 +28,8 @@ DROP FUNCTION IF EXISTS ChangeMail// DROP FUNCTION IF EXISTS GetRateForDisc// +drop function if exists InternalIsTeacherBound// + # ------------------------------------------------------------------------------------------- # Label: abbreviations @@ -84,8 +86,8 @@ END // # check, that teacher teach this course -drop function if exists InternalIsTeacherBounded// -CREATE FUNCTION `InternalIsTeacherBounded` ( +DROP FUNCTION IF EXISTS InternalIsTeacherBound// +CREATE FUNCTION InternalIsTeacherBound ( `pTeacherID` INT, `pDisciplineID` INT ) RETURNS BOOLEAN @@ -123,7 +125,7 @@ DROP FUNCTION IF EXISTS SetExamPeriodOption// CREATE FUNCTION `SetExamPeriodOption` ( `pStudentID` INT, `pSubmoduleID` INT, - `pType` VARCHAR(30) CHARSET utf8 # enum('absence','pass') + `pType` enum('absence','pass') ) RETURNS int(11) NO SQL BEGIN @@ -132,13 +134,13 @@ BEGIN INSERT INTO `exam_period_options` (StudentID, SubmoduleID, Type) VALUES(pStudentID, pSubmoduleID, pType) ON DUPLICATE KEY UPDATE - exam_period_options.Type = pType; + exam_period_options.Type = pType; RETURN 0; END // -# check, if any module is created +# check, regular + exam rate == 100 DROP FUNCTION IF EXISTS InternalIsMapCreated// CREATE FUNCTION `InternalIsMapCreated` ( `pDisciplineID` INT @@ -193,7 +195,7 @@ CREATE FUNCTION `SetSettings` ( NO SQL BEGIN INSERT INTO `general_settings` - (Val, ValS, Name) VALUES(pVal, pValS, pKey) + (Val, ValS, Name) VALUES (pVal, pValS, pKey) ON DUPLICATE KEY UPDATE general_settings.Val = pVal, general_settings.ValS = pValS; @@ -210,7 +212,7 @@ CREATE FUNCTION `SetBitmaskByPagename` ( NO SQL BEGIN INSERT INTO `page_access` - (Pagename, Bitmask) VALUES(pPagename, pMask) + (Pagename, Bitmask) VALUES (pPagename, pMask) ON DUPLICATE KEY UPDATE page_access.Bitmask = pMask; RETURN 0; @@ -241,6 +243,7 @@ END // # Label: semesters # ------------------------------------------------------------------------------------------- +# TODO: deprecated # set current(for user) semester, life time - db session DROP FUNCTION IF EXISTS SetSemesterID// CREATE FUNCTION `SetSemesterID` (`pSemesterID` INT) RETURNS int(11) @@ -256,11 +259,12 @@ END // # Label: faculties # ------------------------------------------------------------------------------------------- +# TODO: return faculty id DROP FUNCTION IF EXISTS CreateFaculty // CREATE FUNCTION CreateFaculty ( - `pFacultyName` VARCHAR(100) CHARSET utf8, - `pFacultyAbbr` VARCHAR(20) CHARSET utf8 - ) RETURNS INT(11) + `pFacultyName` TEXT CHARSET utf8, + `pFacultyAbbr` TEXT CHARSET utf8 + ) RETURNS INT(11) # 0 - success NO SQL BEGIN DECLARE EXIT HANDLER FOR SQLEXCEPTION RETURN -1; @@ -274,6 +278,7 @@ END // # Label: departments # ------------------------------------------------------------------------------------------- +# create department or return existing DROP FUNCTION IF EXISTS CreateDepartment // CREATE FUNCTION CreateDepartment ( `pName` VARCHAR(200) CHARSET utf8, @@ -284,27 +289,55 @@ BEGIN DECLARE EXIT HANDLER FOR SQLEXCEPTION RETURN -1; INSERT INTO departments - (Name, FacultyID) VALUES(pName, pFacultyID); + (Name, FacultyID) VALUES (pName, pFacultyID) + ON DUPLICATE KEY UPDATE + departments.ID = LAST_INSERT_ID(departments.ID); - IF ROW_COUNT() = 0 THEN - RETURN -1; - ELSE - RETURN LAST_INSERT_ID(); - END IF; + RETURN LAST_INSERT_ID(); + +END // + +# ------------------------------------------------------------------------------------------- +# Label: specializations +# ------------------------------------------------------------------------------------------- + + + +# ------------------------------------------------------------------------------------------- +# 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 vGradeID INT DEFAULT -1; + DECLARE EXIT HANDLER FOR SQLEXCEPTION RETURN -1; + + 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: study groups +# 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) + `pGradeID` INT, + `pGroupNum` INT, + `pSpecializationID` INT, + `pGroupName` VARCHAR(50) CHARSET utf8 +) RETURNS int(11) # group id NO SQL BEGIN # check GradeID, SpecID constraints and (GradeID, GroupNum, SpecID) - unique @@ -313,11 +346,15 @@ BEGIN # create discipline INSERT INTO `study_groups` (GradeID, GroupNum, SpecializationID, Name) - VALUES (pGradeID, pGroupNum, pSpecializationID, pGroupName); - RETURN 0; + 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, @@ -329,7 +366,7 @@ BEGIN DECLARE vGroupID INT DEFAULT -1; SELECT study_groups.ID INTO vGroupID - FROM study_groups + FROM `study_groups` INNER JOIN `specializations` ON specializations.ID = study_groups.SpecializationID WHERE study_groups.GradeID = pGradeID AND study_groups.GroupNum = pGroupNum AND @@ -340,6 +377,8 @@ BEGIN END // + + # ------------------------------------------------------------------------------------------- # Label: subjects # ------------------------------------------------------------------------------------------- @@ -347,7 +386,7 @@ END // DROP FUNCTION IF EXISTS CreateSubject// CREATE FUNCTION `CreateSubject` ( `pFacultyID` INT, - `pSubjectName` VARCHAR(200) CHARSET utf8, + `pSubjectName` TEXT CHARSET utf8, `pSubjectAbbr` VARCHAR(20) CHARSET utf8 ) RETURNS int(11) NO SQL @@ -356,7 +395,7 @@ BEGIN # create/get subject (subject name is unique key) INSERT INTO `subjects` - (Name, Abbr) VALUES(pSubjectName, pSubjectAbbr) + (Name, Abbr) VALUES (pSubjectName, pSubjectAbbr) ON DUPLICATE KEY UPDATE subjects.ID = LAST_INSERT_ID(subjects.ID); SET vSubjectID = LAST_INSERT_ID(); @@ -366,8 +405,7 @@ BEGIN # try to attach subject to faculty INSERT INTO `subjects_faculties` - (SubjectID, FacultyID) - VALUES (vSubjectID, pFacultyID) + (SubjectID, FacultyID) VALUES (vSubjectID, pFacultyID) ON DUPLICATE KEY UPDATE # just stub subjects_faculties.ID = LAST_INSERT_ID(subjects_faculties.ID); END; @@ -379,17 +417,18 @@ END // DROP FUNCTION IF EXISTS DeleteSubject // CREATE FUNCTION DeleteSubject ( `pSubjectID` INT - ) RETURNS TEXT + ) RETURNS INT(11) # 0 - success NO SQL BEGIN - DECLARE vChecker INT DEFAULT -1; + DECLARE vChecker BOOLEAN DEFAULT FALSE; DECLARE EXIT HANDLER FOR SQLEXCEPTION RETURN -1; - SELECT disciplines.ID INTO vChecker - FROM `disciplines` + SET vChecker = EXISTS( + SELECT * FROM `disciplines` WHERE disciplines.SubjectID = pSubjectID - LIMIT 1; - IF vChecker > 0 THEN + LIMIT 1 + ); + IF vChecker THEN RETURN -1; # Удаляемый предмет используется в disciplines. END IF; @@ -414,7 +453,7 @@ DROP FUNCTION IF EXISTS CheckAccountExistence// CREATE FUNCTION `CheckAccountExistence` ( `pData` TEXT CHARSET utf8, `pType` enum('login','email', 'code') - ) RETURNS int(11) + ) RETURNS BOOLEAN # TRUE - exist, FALSE - doesn't NO SQL BEGIN DECLARE vRes BOOLEAN DEFAULT FALSE; @@ -458,8 +497,9 @@ BEGIN IF ( ROW_COUNT() = 0 ) THEN RETURN -2; # account with this Code not found + ELSE + RETURN @vAccountID; END IF; - RETURN @vAccountID; END // @@ -563,7 +603,7 @@ CREATE FUNCTION `CreateTeacher` ( `pJobPositionID` INT, `pDepartmentID` INT, `pActivationCode` VARCHAR(40) CHARSET utf8 - ) RETURNS int(11) + ) RETURNS int(11) # 0 - success, <0 failed NO SQL BEGIN DECLARE vAccountID INT DEFAULT -1; @@ -599,19 +639,9 @@ BEGIN DECLARE vAccountID, vRoleID, vDepID INT DEFAULT -1; DECLARE EXIT HANDLER FOR SQLEXCEPTION RETURN -1; - # try to find a department with same name \pDepartmentName - SELECT departments.ID INTO vDepID - FROM `departments` - WHERE departments.Name = pDepartmentName AND - departments.FacultyID = pFacultyID - LIMIT 1; - - IF vDepID <= 0 THEN - # pDepartmentName is not empty now - SET vDepID = CreateDepartment(pDepartmentName, pFacultyID); - IF vDepID < 0 THEN - RETURN -1; - END IF; + SET vDepID = CreateDepartment(pDepartmentName, pFacultyID); + IF vDepID < 0 THEN + RETURN -1; END IF; RETURN CreateTeacher(pLastName, pFirstName, pSecondName, 12, vDepID, pActivationCode); @@ -628,22 +658,19 @@ CREATE FUNCTION `GetEditRightsForTeacher` ( ) RETURNS int(11) NO SQL BEGIN - DECLARE vUserRole, vDiscTeacherID INT DEFAULT -1; - - SELECT disciplines_teachers.ID INTO vDiscTeacherID - FROM `disciplines_teachers` - WHERE disciplines_teachers.DisciplineID = pDisciplineID AND - disciplines_teachers.TeacherID = pTeacherID - LIMIT 1; + DECLARE vUserRole INT DEFAULT -1; + DECLARE vIsBound BOOLEAN; - IF vDiscTeacherID > 0 THEN + SET vIsBound = InternalIsTeacherBound(pTeacherID, pDisciplineID); + IF vIsBound > 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; + WHERE teachers.ID = pTeacherID + LIMIT 1; IF vUserRole = 4 THEN # 4 - сотрудник деканата RETURN 0; END IF; @@ -659,6 +686,7 @@ END // # TODO: magic constants (UserRoleID) # TODO: transaction +# TODO: group id instead num and grade DROP FUNCTION IF EXISTS CreateStudent// CREATE FUNCTION `CreateStudent` ( `pLastName` VARCHAR(30) CHARSET utf8, @@ -698,7 +726,6 @@ BEGIN WHERE general_settings.Name = 'SemesterID' LIMIT 1; - # TODO: add param semester id\ instead @currentSemesterID RETURN ControlStudentGroup(vStudentID, vGroupID, FALSE, vSemesterID); END // @@ -711,7 +738,7 @@ CREATE FUNCTION `CreateStudentEx` ( `pSecondName` VARCHAR(30) CHARSET utf8, `pGradeNum` INT, `pGroupNum` INT, - `pDegree` VARCHAR(20) CHARSET utf8, + `pDegree` enum('bachelor', 'master', 'specialist'), `pSpecName` VARCHAR(50) CHARSET utf8, `pFacultyID` INT, `pActivationCode` VARCHAR(40) CHARSET utf8 @@ -721,56 +748,15 @@ 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(); - # TODO: extract CreateGroup, CreateGrade, ... - - # try to find grade - SELECT grades.ID INTO vGradeID - FROM `grades` - WHERE grades.Num = pGradeNum AND grades.Degree = pDegree - LIMIT 1; - # such grade doesn't exist - IF vGradeID <= 0 THEN - # insert new grade with pGradeNum and pDegree - INSERT INTO `grades` - (Num, Degree) VALUES (pGradeNum, pDegree); - SET vGradeID = LAST_INSERT_ID(); - END IF; - - # try to find group - SELECT view_groups.GroupID INTO vGroupID - FROM `view_groups` - WHERE view_groups.FacultyID = pFacultyID AND - view_groups.GroupNum = pGroupNum AND - view_groups.GradeID = vGradeID - LIMIT 1; - - # group not found - IF vGroupID <= 0 THEN - # try to find specialization - SELECT specializations.ID INTO vSpecID - FROM `specializations` - WHERE (specializations.Name = pSpecName OR - (pSpecName = '' AND specializations.Name IS NULL)) AND - specializations.FacultyID = pFacultyID - LIMIT 1; - - # specialization not found - IF vSpecID <= 0 THEN - # create new specialization - INSERT INTO `specializations` - (Name, Abbr, FacultyID) - VALUES (pSpecName, NULL, pFacultyID); - SET vSpecID = LAST_INSERT_ID(); - END IF; - - # create new group - INSERT INTO `study_groups` - (GradeID, GroupNum, SpecializationID) - VALUES (vGradeID, pGroupNum, vSpecID); - SET vGroupID = LAST_INSERT_ID(); - END IF; - + SET vGradeID = CreateGrade(pGradeNum, pDegree); + SET vGroupID = CreateGroup(vGradeID, pGroupNum, vSpecID, NULL); RETURN CreateStudent(pLastName, pFirstName, pSecondName, vGradeID, pGroupNum, pFacultyID, pActivationCode); END // @@ -805,7 +791,9 @@ BEGIN ELSE INSERT INTO `students_groups` (StudentID, GroupID, SemesterID) - VALUES(pStudentID, pGroupID, pSemesterID); + VALUES(pStudentID, pGroupID, pSemesterID) + ON DUPLICATE KEY UPDATE + students_groups.GroupID = pGroupID; END IF; RETURN ROW_COUNT()-1; END // @@ -956,11 +944,12 @@ DROP FUNCTION IF EXISTS ChangeDisciplineControl// CREATE FUNCTION `ChangeDisciplineControl` ( `pTeacherID` INT, `pDisciplineID` INT, - `pExamType` VARCHAR(30) CHARSET utf8 + `pExamType` enum('exam', 'credit', 'grading_credit') ) RETURNS int(11) NO SQL BEGIN - DECLARE vOldExamType, vChecker, vExtraMax, vExtraID INT DEFAULT -1; + DECLARE vChecker, vExtraMax, vExtraID INT DEFAULT -1; + DECLARE vOldExamType enum('exam', 'credit', 'grading_credit') DEFAULT -1; DECLARE EXIT HANDLER FOR SQLEXCEPTION RETURN -1; IF InternalIsMapLocked(pDisciplineID) OR @@ -987,7 +976,7 @@ BEGIN LIMIT 1; # check type changing: exam <-> credit/grading_credit - IF vOldExamType = 1 XOR pExamType != 'exam' THEN # 1 - exam + IF vOldExamType = 'exam' XOR pExamType != 'exam' THEN RETURN 0; END IF; @@ -1247,7 +1236,7 @@ CREATE FUNCTION `BindTeacher` ( `pAuthorTeacherID` INT, `pBindingTeacherID` INT, `pDisciplineID` INT - ) RETURNS int(11) + ) RETURNS int(11) # 0 - if was attached (or already bound) NO SQL BEGIN DECLARE EXIT HANDLER FOR SQLEXCEPTION RETURN -1; @@ -1300,7 +1289,7 @@ BEGIN IF pAuthorTeacherID = pNewAuthorID OR NOT InternalIsTeacherAuthor(pAuthorTeacherID, pDisciplineID) OR - NOT InternalIsTeacherBounded(pNewAuthorID, pDisciplineID) + NOT InternalIsTeacherBound(pNewAuthorID, pDisciplineID) THEN RETURN -1; END IF; @@ -2147,7 +2136,7 @@ BEGIN # 2) check, you can't rate regular and bonus after milestone # 3) check, max rate exceeding IF NOT InternalIsStudentAttached(pStudentID, vDisciplineID, @CurrentSemesterID) OR - NOT InternalIsTeacherBounded(pTeacherID, vDisciplineID) OR + NOT InternalIsTeacherBound(pTeacherID, vDisciplineID) OR pRate > vMaxRate OR (vIsOver AND (vModuleType = 1 OR vModuleType = 3)) # 1 - regular, 3 - bonus THEN @@ -2286,22 +2275,23 @@ BEGIN DECLARE vUserFullName VARCHAR(255) charset utf8; DECLARE vChecker INT DEFAULT -1; - SELECT students.ID As ID, CONCAT(students.LastName,' ',students.FirstName,' ',students.SecondName) As UserName - INTO vChecker, vUserFullName - FROM `students` - WHERE students.AccountID = pAccountID - LIMIT 1; - - IF vChecker <= 0 THEN - SELECT teachers.ID As ID, CONCAT(teachers.LastName,' ',teachers.FirstName,' ',teachers.SecondName) As UserName - INTO vChecker, vUserFullName - FROM `teachers` - WHERE teachers.AccountID = pAccountID - LIMIT 1; - - IF vChecker <= 0 THEN - RETURN ''; - END IF; + # 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;