From 8b9627c081425728417eb4f05c93395153ea7f58 Mon Sep 17 00:00:00 2001 From: PavelBegunkov <asml.Silence@gmail.com> Date: Fri, 13 Feb 2015 23:33:27 +0300 Subject: [PATCH] REF: stored functions optimization --- db/StoredProcedures.sql | 1043 ++++++++++++--------------------------- db/Views.sql | 6 +- db/fix.sql | 9 + 3 files changed, 320 insertions(+), 738 deletions(-) diff --git a/db/StoredProcedures.sql b/db/StoredProcedures.sql index d31ac441c..81eb87b52 100644 --- a/db/StoredProcedures.sql +++ b/db/StoredProcedures.sql @@ -20,15 +20,8 @@ DROP FUNCTION IF EXISTS InternalIsMapLocked// CREATE FUNCTION `InternalIsMapLocked` (`pDisciplineID` INT) RETURNS boolean NO SQL -BEGIN - DECLARE vChecker INT DEFAULT -1; - - SELECT disciplines.IsLocked - INTO vChecker - FROM `disciplines` - WHERE disciplines.ID = pDisciplineID - LIMIT 1; - RETURN ( vChecker > 0 ); +BEGIN + RETURN (EXISTS(SELECT * FROM `disciplines` WHERE disciplines.ID = pDisciplineID)); END // @@ -334,24 +327,10 @@ CREATE FUNCTION `SetBitmaskByPagename` (`pPagename` TEXT CHARSET utf8, `pMask` INT) RETURNS int(11) NO SQL BEGIN - DECLARE vChecker INT DEFAULT -1; - SELECT page_access.ID - INTO vChecker - FROM `page_access` - WHERE page_access.Pagename = pPagename - LIMIT 1; - - IF vChecker > 0 THEN - UPDATE `page_access` - SET page_access.Bitmask = pMask - WHERE page_access.Pagename = pPagename - LIMIT 1; - ELSE - INSERT INTO `page_access` - (Pagename, Bitmask) - VALUES (pPagename, pMask); - END IF; - + INSERT INTO `page_access` + (Pagename, Bitmask) VALUES(pPagename, pMask) + ON DUPLICATE KEY UPDATE + page_access.Bitmask = pMask; RETURN 0; END // @@ -404,24 +383,16 @@ DROP FUNCTION IF EXISTS SetCurSemesterID// CREATE FUNCTION `SetCurSemesterID` (`pSemesterID` INT) RETURNS int(11) NO SQL BEGIN - DECLARE vChecker INT DEFAULT -1; - - SELECT semesters.ID - INTO vChecker - FROM `semesters` - WHERE semesters.ID = pSemesterID - LIMIT 1; - - IF semesters.ID <= 0 THEN - INSERT INTO `general_settings` - (ID, Val) - VALUES (1, pSemesterID); - ELSE - UPDATE `general_settings` - SET general_settings.Val = pSemesterID - WHERE general_settings.ID = 1 - LIMIT 1; + DECLARE vChecker BOOLEAN; + SET vChecker = EXISTS(SELECT * FROM `semesters` WHERE semesters.ID = pSemesterID); + IF !vChecker THEN + RETURN -1; END IF; + + INSERT INTO `general_settings` + (ID, Val) VALUES(1, pSemesterID) + ON DUPLICATE KEY UPDATE + general_settings.Val = pSemesterID; RETURN 0; END // @@ -584,37 +555,14 @@ CREATE FUNCTION `CreateStudyGroup` `pSpecializationID` INT, `pGroupName` VARCHAR(50) CHARSET utf8 ) RETURNS int(11) NO SQL -BEGIN - DECLARE vChecker INT DEFAULT -1; - - # check for grade (GradeID) existence - SELECT grades.ID - INTO vChecker - FROM `grades` - INNER JOIN `specializations` ON pSpecializationID = specializations.ID - WHERE pGradeID = grades.ID - LIMIT 1; - IF vChecker <= 0 OR pGroupName IS NULL THEN - RETURN -1; - END IF; - - # check, that such discipline already created - SET vChecker = -1; - SELECT study_groups.ID - INTO vChecker - FROM `study_groups` - WHERE pGradeID = study_groups.GradeID AND - pGroupNum = study_groups.GroupNum AND - pSpecializationID = study_groups.SpecializationID - LIMIT 1; - IF vChecker > 0 THEN - RETURN -1; - END IF; +BEGIN + # check GradeID, SpecID constraints and (GradeID, GroupNum, SpecID) - unique + DECLARE EXIT HANDLER FOR SQLEXCEPTION RETURN -1; # create discipline INSERT INTO `study_groups` - (GradeID, GroupNum, SpecializationID, Name ) - VALUES (pGradeID, pGroupNum, pSpecializationID, pGroupName); + (GradeID, GroupNum, SpecializationID, Name) + VALUES (pGradeID, pGroupNum, pSpecializationID, pGroupName); RETURN 0; END // @@ -624,14 +572,14 @@ CREATE PROCEDURE `GetStudyGroups` (IN `pGradeID` INT, IN `pFacultyID` INT) NO SQL BEGIN - SELECT view_study_groups.GroupID AS 'ID', - view_study_groups.GroupNum, - view_study_groups.SpecName, - view_study_groups.SpecAbbr - FROM `view_study_groups` - WHERE view_study_groups.GradeID = pGradeID AND - view_study_groups.FacultyID = pFacultyID - ORDER BY view_study_groups.GroupNum ASC; + SELECT view_groups.GroupID AS 'ID', + view_groups.GroupNum, + 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 // @@ -640,18 +588,18 @@ DROP PROCEDURE IF EXISTS GetStudyGroupsForDiscipline// CREATE PROCEDURE `GetStudyGroupsForDiscipline` (IN `pDisciplineID` INT) NO SQL BEGIN - SELECT view_study_groups.GroupID AS 'ID', - view_study_groups.GroupNum, - view_study_groups.GradeID, - view_study_groups.GradeNum, - view_study_groups.Degree, - view_study_groups.SpecID, - view_study_groups.SpecName, - view_study_groups.SpecAbbr + 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_study_groups` ON disciplines_groups.GroupID = view_study_groups.GroupID + INNER JOIN `view_groups` ON disciplines_groups.GroupID = view_groups.GroupID WHERE disciplines_groups.DisciplineID = pDisciplineID - ORDER BY view_study_groups.GradeID ASC, view_study_groups.GroupID ASC; + ORDER BY view_groups.GradeID ASC, view_groups.GroupID ASC; END // # get all study groups, that takes this course, including groups with attached students @@ -692,49 +640,29 @@ CREATE FUNCTION `CreateSubject` ) RETURNS int(11) NO SQL BEGIN - DECLARE vChecker, vSubjectID INT DEFAULT -1; - - SELECT subjects.ID - INTO vSubjectID + DECLARE vSubjectID INT DEFAULT -1; + + # find same subject + SELECT subjects.ID INTO vSubjectID FROM `subjects` - WHERE pSubjectName = subjects.Name + WHERE subjects.Name = pSubjectName LIMIT 1; - - IF vSubjectID <= 0 THEN - # subject with this name doesn't exist - - # create subject + IF vSubjectID <= 0 THEN + # create new subject INSERT INTO `subjects` - (Name, Abbr) - VALUES (pSubjectName, pSubjectAbbr); - - # get it's id - SELECT subjects.ID - INTO vSubjectID - FROM `subjects` - WHERE subjects.Name = pSubjectName - LIMIT 1; - IF vSubjectID <= 0 THEN - RETURN -1; - END IF; - ELSE - # subject extst - # if subject already attached to faculty, then exit - SELECT subjects_faculties.ID - INTO vChecker - FROM `subjects_faculties` - WHERE subjects_faculties.FacultyID = pFacultyID AND - subjects_faculties.SubjectID = vSubjectID - LIMIT 1; - IF vChecker > 0 THEN - RETURN 0; - END IF; - END IF; - - # attach subject to faculty - INSERT INTO `subjects_faculties` - (SubjectID, FacultyID) - VALUES (vSubjectID, pFacultyID); + (Name, Abbr) VALUES(pSubjectName, pSubjectAbbr); + SET vSubjectID = LAST_INSERT_ID(); + END IF; + + BEGIN # handler block + DECLARE EXIT HANDLER FOR SQLEXCEPTION RETURN -1; + # try to attach subject to faculty + INSERT INTO `subjects_faculties` + (SubjectID, FacultyID) + VALUES (vSubjectID, pFacultyID) + ON DUPLICATE KEY UPDATE # just stub + subjects_faculties.FacultyID = subjects_faculties.FacultyID; + END; RETURN 0; END // @@ -765,11 +693,7 @@ DROP FUNCTION IF EXISTS GetAccCountByCode// CREATE FUNCTION `GetAccCountByCode` (`pCode` VARCHAR(40) CHARSET utf8) RETURNS int(11) NO SQL BEGIN - RETURN( SELECT COUNT(*) - FROM `accounts` - WHERE accounts.ActivationCode = pCode - LIMIT 1 - ); + RETURN EXISTS(SELECT * FROM `accounts` WHERE accounts.ActivationCode = pCode); END // @@ -777,11 +701,7 @@ DROP FUNCTION IF EXISTS GetAccCountByMail // CREATE FUNCTION `GetAccCountByMail` (`pEMail` VARCHAR(50) CHARSET utf8) RETURNS int(11) NO SQL BEGIN - RETURN( SELECT COUNT(*) - FROM `accounts` - WHERE accounts.EMail = pEMail - LIMIT 1 - ); + RETURN EXISTS(SELECT * FROM `accounts` WHERE accounts.EMail = pEMail); END // @@ -789,15 +709,10 @@ DROP FUNCTION IF EXISTS GetAccCountByLogin// CREATE FUNCTION `GetAccCountByLogin` (`pLogin` VARCHAR(50) CHARSET utf8) RETURNS int(11) NO SQL BEGIN - RETURN( SELECT COUNT(*) - FROM `accounts` - WHERE accounts.Login = pLogin - LIMIT 1 - ); + RETURN EXISTS(SELECT * FROM `accounts` WHERE accounts.Login = pLogin); END // - DROP PROCEDURE IF EXISTS GetAccountInfo// CREATE PROCEDURE `GetAccountInfo` ( IN `pUserID` INT ) NO SQL @@ -818,7 +733,6 @@ BEGIN END // - DROP PROCEDURE IF EXISTS GetPersonalInfo// CREATE PROCEDURE `GetPersonalInfo` ( IN `pUserID` INT ) NO SQL @@ -881,28 +795,19 @@ CREATE FUNCTION `ActivateAccount` ) RETURNS int(11) NO SQL BEGIN - DECLARE vChecker, vUserID INT DEFAULT -1; - - # check for matching with existing accounts (note: Login & E-Mail are unique) - SELECT accounts.ID - INTO vChecker - FROM `accounts` - WHERE accounts.Login = pLogin OR - accounts.EMail = pEMail - LIMIT 1; - IF vChecker > 0 OR pPassword IS NULL THEN - RETURN -1; - END IF; + DECLARE vUserID INT DEFAULT -1; + # check for matching with existing accounts (note: Login & E-Mail are unique) + DECLARE EXIT HANDLER FOR SQLEXCEPTION RETURN -1; # check for existing of accounts with such Code SELECT accounts.ID - INTO vUserID + INTO vUserID FROM `accounts` WHERE accounts.ActivationCode = pCode LIMIT 1; - IF vUserID <= 0 THEN - RETURN -2; - END IF; + IF vUserID <= 0 THEN + RETURN -2; + END IF; # activate account UPDATE `accounts` @@ -923,24 +828,14 @@ CREATE FUNCTION `ChangePassword` ) RETURNS int(11) NO SQL BEGIN - DECLARE vChecker INT DEFAULT -1; - - # check account with UserID - SELECT accounts.ID - INTO vChecker - FROM `accounts` - WHERE accounts.ID = pUserID - LIMIT 1; - IF vChecker <= 0 OR pPassword IS NULL THEN - RETURN -1; - END IF; + DECLARE EXIT HANDLER FOR SQLEXCEPTION RETURN -1; # set new password UPDATE `accounts` SET accounts.Password = pPassword WHERE accounts.ID = pUserID LIMIT 1; - RETURN 0; + RETURN ROW_COUNT()-1; # -1 if account doesn't exists, otherwise 0 END // @@ -951,74 +846,34 @@ CREATE FUNCTION `ChangeLogin` ) RETURNS int(11) NO SQL BEGIN - DECLARE vChecker INT DEFAULT -1; - - # check for account with UserID - SELECT accounts.ID - INTO vChecker - FROM `accounts` - WHERE accounts.ID = pUserID - LIMIT 1; - IF vChecker <= 0 THEN - RETURN -1; - END IF; - - # search accounts with Login (login must be unique) - SET vChecker = -1; - SELECT accounts.ID - INTO vChecker - FROM `accounts` - WHERE accounts.Login = pLogin - LIMIT 1; - IF vChecker > 0 THEN - RETURN -1; - END IF; + # check set login: login - unique + DECLARE EXIT HANDLER FOR SQLEXCEPTION RETURN -1; # set new login UPDATE `accounts` SET accounts.Login = pLogin WHERE accounts.ID = pUserID LIMIT 1; - RETURN 0; + RETURN ROW_COUNT()-1; # -1 if account doesn't exists, otherwise 0 END // DROP FUNCTION IF EXISTS ChangeMail// CREATE FUNCTION `ChangeMail` - ( `pUserID` INT, `pEMail` VARCHAR(50) CHARSET utf8 + (`pUserID` INT, `pEMail` VARCHAR(50) CHARSET utf8 ) RETURNS int(11) NO SQL BEGIN - DECLARE vChecker INT DEFAULT -1; - - # check for account with UserID - SELECT accounts.ID - INTO vChecker - FROM `accounts` - WHERE accounts.ID = pUserID - LIMIT 1; - IF vChecker <= 0 THEN - RETURN -1; - END IF; - - # search accounts with EMail (e-mail must be unique) - SET vChecker = -1; - SELECT accounts.ID - INTO vChecker - FROM `accounts` - WHERE accounts.EMail = pEMail - LIMIT 1; - IF vChecker > 0 THEN - RETURN -1; - END IF; + # check set login: login - unique + DECLARE EXIT HANDLER FOR SQLEXCEPTION RETURN -1; # set new e-mail UPDATE `accounts` SET accounts.EMail = pEMail WHERE accounts.ID = pUserID LIMIT 1; - RETURN 0; + RETURN ROW_COUNT()-1; # -1 if account doesn't exists, otherwise 0 END // @@ -1043,11 +898,9 @@ BEGIN RETURN -1; END IF; - # loging + # logging INSERT INTO `logs_signin` - (AccountID) - VALUES (vAccountID); - + (AccountID) VALUES (vAccountID); RETURN vAccountID; END // @@ -1069,24 +922,8 @@ CREATE FUNCTION `ChangeTeacherInfo` `pDepartmentID` INT ) RETURNS int(11) NO SQL -BEGIN - DECLARE vChecker INT DEFAULT -1; - - # check existing of Teacher, jobPosition & Department - SELECT teachers.ID - INTO vChecker - FROM `teachers` - INNER JOIN `job_positions` ON job_positions.ID = pJobPositionID - INNER JOIN `departments` ON departments.ID = pDepartmentID - WHERE pTeacherID = teachers.ID - LIMIT 1; - IF vChecker <= 0 OR - pLastName IS NULL OR - pSecondName IS NULL OR - pFirstName IS NULL - THEN - RETURN -1; - END IF; +BEGIN + DECLARE EXIT HANDLER FOR SQLEXCEPTION RETURN -1; # set new info UPDATE `teachers` @@ -1097,7 +934,7 @@ BEGIN teachers.DepartmentID = pDepartmentID WHERE teachers.ID = pTeacherID LIMIT 1; - RETURN 0; + RETURN ROW_COUNT()-1; # -1 if teacher doesn't exists, otherwise 0 END // @@ -1212,60 +1049,24 @@ CREATE FUNCTION `CreateTeacher` `pDepartmentID` INT, `pActivationCode` VARCHAR(40) CHARSET utf8 ) RETURNS int(11) -NO SQL - BEGIN - DECLARE vAccountID, vChecker, vRoleID INT DEFAULT -1; - -# check input params - IF pActivationCode IS NULL OR pLastName IS NULL OR pFirstName IS NULL THEN - RETURN -1; - END IF; - -# check Department & jobPosition existing - SELECT departments.ID - INTO vChecker - FROM `departments` - INNER JOIN `job_positions` ON job_positions.ID = pJobPositionID - WHERE departments.ID = pDepartmentID - LIMIT 1; - IF vChecker <= 0 THEN - RETURN -1; - END IF; - -# search accounts with same Code - SELECT accounts.ID - INTO vAccountID - FROM `accounts` - WHERE accounts.ActivationCode = pActivationCode - LIMIT 1; - IF vAccountID > 0 THEN - RETURN -2; - END IF; + NO SQL +BEGIN + DECLARE vAccountID INT DEFAULT -1; + DECLARE EXIT HANDLER FOR SQLEXCEPTION RETURN -1; # user role 2 - common teacher # add new account - INSERT INTO `accounts` - ( Login , Password , EMail, UserRoleID, ActivationCode ) + INSERT INTO `accounts` + (Login , Password , EMail, UserRoleID, ActivationCode ) VALUES ( NULL, NULL, NULL, 2, pActivationCode); - - -# get this account ID - SET vAccountID = -1; - SELECT accounts.ID - INTO vAccountID - FROM `accounts` - WHERE accounts.ActivationCode = pActivationCode - LIMIT 1; - IF vAccountID <= 0 THEN - RETURN -3; - END IF; + SET vAccountID = LAST_INSERT_ID(); # add new teacher - INSERT INTO `teachers` - ( AccountID, LastName, FirstName, SecondName, JobPositionID, DepartmentID) + INSERT INTO `teachers` + (AccountID, LastName, FirstName, SecondName, JobPositionID, DepartmentID) VALUES (vAccountID, pLastName, pFirstName, pSecondName, pJobPositionID, pDepartmentID); - RETURN 0; - END // + RETURN ROW_COUNT()-1; +END // # TODO: check necessary @@ -1277,67 +1078,33 @@ CREATE FUNCTION `CreateTeacherByDepName` `pDepartmentName` VARCHAR(200) CHARSET utf8, `pActivationCode` VARCHAR(40) CHARSET utf8 ) RETURNS int(11) -NO SQL - BEGIN - DECLARE vAccountID, vChecker, vRoleID, vDepID INT DEFAULT -1; - -# check input params - IF pActivationCode IS NULL OR pLastName IS NULL OR pFirstName IS NULL THEN - RETURN -1; - END IF; + NO SQL +BEGIN + DECLARE vAccountID, vChecker, vRoleID, vDepID INT DEFAULT -1; + DECLARE EXIT HANDLER FOR SQLEXCEPTION RETURN -1; # try to find a department with pDepartmentName - SELECT departments.ID + SELECT departments.ID INTO vDepID FROM `departments` WHERE departments.Name = pDepartmentName OR (pDepartmentName = '' AND departments.Name IS NULL) # or stub department record LIMIT 1; - IF vDepID <= 0 THEN - RETURN -1; - END IF; - -# TODO: hard code '12' -# try to find default job_position - SELECT job_positions.ID - INTO vChecker - FROM `job_positions` - WHERE job_positions.ID = 12 - LIMIT 1; - IF vChecker <= 0 THEN - RETURN -1; - END IF; - - SELECT accounts.ID - INTO vAccountID - FROM `accounts` - WHERE accounts.ActivationCode = pActivationCode - LIMIT 1; - IF vAccountID > 0 THEN - RETURN -2; - END IF; - -# TODO: user roles - INSERT INTO `accounts` - ( Login , Password , EMail, UserRoleID, ActivationCode ) - VALUES ( NULL, NULL, NULL, 2, pActivationCode); + IF vDepID <= 0 THEN + RETURN -1; + END IF; - SET vAccountID = -1; - SELECT accounts.ID - INTO vAccountID - FROM `accounts` - WHERE accounts.ActivationCode = pActivationCode - LIMIT 1; - IF vAccountID <= 0 THEN - RETURN -3; - END IF; + INSERT INTO `accounts` + (Login , Password , EMail, UserRoleID, ActivationCode ) + VALUES ( NULL, NULL, NULL, 2, pActivationCode); + SET vAccountID = LAST_INSERT_ID(); - INSERT INTO `teachers` - ( AccountID, LastName, FirstName, SecondName, JobPositionID, DepartmentID) - VALUES (vAccountID, pLastName, pFirstName, pSecondName, 12, vDepID); - RETURN 0; - END // + INSERT INTO `teachers` + (AccountID, LastName, FirstName, SecondName, JobPositionID, DepartmentID) + VALUES (vAccountID, pLastName, pFirstName, pSecondName, 12, vDepID); + RETURN 0; +END // @@ -1497,54 +1264,29 @@ CREATE FUNCTION `CreateStudent` NO SQL BEGIN DECLARE vAccountID, vGroupID INT DEFAULT -1; - - # check input params - IF pActivationCode IS NULL OR pLastName IS NULL OR pFirstName IS NULL THEN - RETURN -1; - END IF; + DECLARE EXIT HANDLER FOR SQLEXCEPTION RETURN -1; # find group - SELECT view_study_groups.GroupID - INTO vGroupID - FROM `view_study_groups` - WHERE view_study_groups.FacultyID = pFacultyID AND - view_study_groups.GradeID = pGradeID AND - view_study_groups.GroupNum = pGroupNum + SELECT view_groups.GroupID INTO vGroupID + FROM `view_groups` + WHERE view_groups.FacultyID = pFacultyID AND + view_groups.GradeID = pGradeID AND + view_groups.GroupNum = pGroupNum LIMIT 1; IF vGroupID <= 0 THEN RETURN -1; END IF; - # try to find account with same activation code - SELECT accounts.ID - INTO vAccountID - FROM `accounts` - WHERE accounts.ActivationCode = pActivationCode - LIMIT 1; - IF vAccountID > 0 THEN - RETURN -2; - END IF; - # create new account INSERT INTO `accounts` - ( Login , Password , EMail, UserRoleID, ActivationCode ) + (Login , Password , EMail, UserRoleID, ActivationCode ) VALUES ( NULL, NULL, NULL, 1, pActivationCode); - - # get created account ID - SET vAccountID = -1; - SELECT accounts.ID - INTO vAccountID - FROM `accounts` - WHERE accounts.ActivationCode = pActivationCode - LIMIT 1; - IF vAccountID <= 0 THEN - RETURN -3; - END IF; + SET vAccountID = LAST_INSERT_ID(); # create student INSERT INTO `students` - (GroupID, AccountID, LastName, FirstName, SecondName) - VALUES (vGroupID, vAccountID, pLastName, pFirstName, pSecondName); + (GroupID, AccountID, LastName, FirstName, SecondName) + VALUES (vGroupID, vAccountID, pLastName, pFirstName, pSecondName); RETURN 0; END // @@ -1564,45 +1306,33 @@ CREATE FUNCTION `CreateStudentEx` NO SQL BEGIN DECLARE vAccountID, vGradeID, vSpecID, vGroupID INT DEFAULT -1; - - IF pActivationCode IS NULL OR pLastName IS NULL OR pFirstName IS NULL THEN - RETURN -1; - END IF; + DECLARE EXIT HANDLER FOR SQLEXCEPTION RETURN -1; # try to find grade - SELECT grades.ID - INTO vGradeID + SELECT grades.ID INTO vGradeID FROM `grades` - WHERE grades.Num = pGradeNum AND - grades.Degree = pDegree + 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); - - # find inserted grade + (Num, Degree) VALUES (pGradeNum, pDegree); SET vGradeID = LAST_INSERT_ID(); END IF; # try to find group - SELECT view_study_groups.GroupID - INTO vGroupID - FROM `view_study_groups` - WHERE view_study_groups.FacultyID = pFacultyID AND - view_study_groups.GroupNum = pGroupNum AND - view_study_groups.GradeID = vGradeID + 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 + SELECT specializations.ID INTO vSpecID FROM `specializations` WHERE (specializations.Name = pSpecName OR (pSpecName = '' AND specializations.Name IS NULL)) AND @@ -1613,46 +1343,30 @@ BEGIN IF vSpecID <= 0 THEN # create new specialization INSERT INTO `specializations` - (Name, Abbr, FacultyID ) + (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); - + VALUES (vGradeID, pGroupNum, vSpecID); SET vGroupID = LAST_INSERT_ID(); END IF; - # check accounts with such activation code - SELECT accounts.ID - INTO vAccountID - FROM `accounts` - WHERE accounts.ActivationCode = pActivationCode - LIMIT 1; - IF vAccountID > 0 THEN - RETURN -2; - END IF; - # TODO: user roles # create account INSERT INTO `accounts` - ( Login , Password , EMail, UserRoleID, ActivationCode ) + (Login, Password , EMail, UserRoleID, ActivationCode ) VALUES ( NULL, NULL, NULL, 1, pActivationCode); - SET vAccountID = LAST_INSERT_ID(); - IF vAccountID <= 0 THEN - RETURN -3; - END IF; - + # create student INSERT INTO `students` (GroupID, AccountID, LastName, FirstName, SecondName) VALUES (vGroupID, vAccountID, pLastName, pFirstName, pSecondName); - RETURN 0; + RETURN ROW_COUNT()-1; END // @@ -1692,9 +1406,9 @@ BEGIN view_disciplines.GradeID, view_disciplines.GradeNum, view_disciplines.Degree, - view_study_groups.GroupID, - view_study_groups.GroupNum, - view_study_groups.GroupName, + view_groups.GroupID, + view_groups.GroupNum, + view_groups.GroupName, view_disciplines.SubjectID, view_disciplines.SubjectName, (pTeacherID = view_disciplines.AuthorID) AS 'IsAuthor', @@ -1702,7 +1416,7 @@ BEGIN view_disciplines.IsLocked FROM `disciplines_teachers` LEFT JOIN `disciplines_groups` ON disciplines_groups.DisciplineID = disciplines_teachers.DisciplineID - LEFT JOIN `view_study_groups` ON view_study_groups.GroupID = disciplines_groups.GroupID + LEFT JOIN `view_groups` ON view_groups.GroupID = disciplines_groups.GroupID INNER JOIN `view_disciplines` ON disciplines_teachers.DisciplineID = view_disciplines.DisciplineID LEFT JOIN `view_disciplines_results` ON view_disciplines_results.DisciplineID = view_disciplines.DisciplineID WHERE disciplines_teachers.TeacherID = pTeacherID AND @@ -1710,7 +1424,7 @@ BEGIN ORDER BY view_disciplines.GradeID ASC, view_disciplines.SubjectName ASC, view_disciplines.DisciplineID ASC, - view_study_groups.GroupNum ASC; + view_groups.GroupNum ASC; END // @@ -1813,19 +1527,20 @@ BEGIN END // DROP FUNCTION IF EXISTS OrderModuleTypesForSession// -CREATE FUNCTION `OrderModuleTypesForSession` ( IN `ModuleType` INT - ) RETURNS INT(3) +CREATE FUNCTION `OrderModuleTypesForSession` + ( IN `pModuleType` INT ) RETURNS INT(3) NO SQL -BEGIN - DECLARE Res INT; - SET Res = 0; - IF ModuleType = 'extra' THEN SET Res = 1; - ELSEIF ModuleType = 'exam' THEN SET Res = 2; - ELSEIF ModuleType = 'bonus' THEN SET Res = 3; - ELSE SET Res = 4; - END IF; +BEGIN + DECLARE vRes INT DEFAULT 0; + + CASE pModuleType + WHEN 'extra' THEN SET vRes = 1; + WHEN 'exam' THEN SET vRes = 2; + WHEN 'bonus' THEN SET vRes = 3; + ELSE SET vRes = 1; + END CASE; - RETURN Res; + RETURN vRes; END // @@ -1948,31 +1663,16 @@ CREATE FUNCTION `AddDiscipline` NO SQL BEGIN DECLARE vChecker, vDisciplineID INT DEFAULT -1; - - SELECT grades.ID - INTO vChecker - FROM `grades` - INNER JOIN `subjects_faculties` ON subjects_faculties.SubjectID = pSubjectID AND - subjects_faculties.FacultyID = pFacultyID - INNER JOIN `teachers` ON pTeacherID = teachers.ID - WHERE pGradeID = grades.ID - LIMIT 1; - IF vChecker <= 0 THEN - RETURN -1; - END IF; + DECLARE EXIT HANDLER FOR SQLEXCEPTION RETURN -1; INSERT INTO `disciplines` - ( AuthorID, GradeID, SubjectID, ExamType, - LectureCount, PracticeCount,LabCount, - SemesterID,FacultyID - ) - VALUES ( pTeacherID, pGradeID, pSubjectID, pExamType, - pLectureCount, pPracticeCount, pLabCount, - @CurrentSemesterID, pFacultyID ); - + (AuthorID, GradeID, SubjectID, ExamType, LectureCount, PracticeCount,LabCount, SemesterID,FacultyID) + VALUES ( pTeacherID, pGradeID, pSubjectID, pExamType, pLectureCount, pPracticeCount, pLabCount, + @CurrentSemesterID, pFacultyID); SET vDisciplineID = LAST_INSERT_ID(); + INSERT INTO `disciplines_teachers` - ( DisciplineID,TeacherID ) + (DisciplineID,TeacherID) VALUES (vDisciplineID, pTeacherID); IF pExamType = 'exam' THEN @@ -1985,78 +1685,61 @@ END // DROP FUNCTION IF EXISTS ChangeDisciplineSubject// -CREATE FUNCTION `ChangeDisciplineSubject` ( `TeacherID` INT, - `DisciplineID` INT, - `SubjectID` INT - ) RETURNS int(11) +CREATE FUNCTION `ChangeDisciplineSubject` + (`pTeacherID` INT, `pDisciplineID` INT, `pSubjectID` INT + ) RETURNS int(11) NO SQL BEGIN - DECLARE vChecker INT; - - IF NOT InternalIsTeacherAuthor(TeacherID, DisciplineID) OR - InternalIsMapLocked(DisciplineID) - THEN - RETURN -1; - END IF; + DECLARE vChecker INT; + DECLARE EXIT HANDLER FOR SQLEXCEPTION RETURN -1; - SET vChecker = -1; - SELECT subjects.ID - INTO vChecker - FROM `subjects` - WHERE subjects.ID = SubjectID - LIMIT 1; - IF vChecker <= 0 THEN + IF NOT InternalIsTeacherAuthor(pTeacherID, pDisciplineID) OR + InternalIsMapLocked(pDisciplineID) + THEN RETURN -1; END IF; UPDATE `disciplines` - SET disciplines.SubjectID = SubjectID - WHERE disciplines.ID = DisciplineID - LIMIT 1; - RETURN 0; + SET disciplines.SubjectID = pSubjectID + 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 + (`pTeacherID` INT, `pDisciplineID` INT, `pGradeID` INT ) RETURNS int(11) NO SQL BEGIN DECLARE vChecker INT DEFAULT -1; + DECLARE EXIT HANDLER FOR SQLEXCEPTION RETURN -1; - SELECT grades.ID - INTO vChecker - FROM `grades` - WHERE grades.ID = pGradeID - LIMIT 1; - IF vChecker <= 0 OR - InternalIsMapLocked(pDisciplineID) OR + IF InternalIsMapLocked(pDisciplineID) OR NOT InternalIsTeacherAuthor(pTeacherID, pDisciplineID) THEN RETURN -1; END IF; - SELECT disciplines.GradeID - INTO vChecker + SELECT disciplines.GradeID INTO vChecker FROM `disciplines` WHERE disciplines.ID = pDisciplineID LIMIT 1; IF vChecker != pGradeID THEN DELETE FROM `disciplines_groups` - WHERE disciplines_groups.DisciplineID = pDisciplineID; - + WHERE disciplines_groups.DisciplineID = pDisciplineID; DELETE FROM `disciplines_students` - WHERE disciplines_students.DisciplineID = pDisciplineID; + WHERE disciplines_students.DisciplineID = pDisciplineID; END IF; UPDATE `disciplines` - SET disciplines.GradeID = GradeID + SET disciplines.GradeID = pGradeID WHERE disciplines.ID = pDisciplineID LIMIT 1; - RETURN 0; + RETURN ROW_COUNT()-1; END // @@ -2067,7 +1750,8 @@ CREATE FUNCTION `ChangeDisciplineControl` ) RETURNS int(11) NO SQL BEGIN - DECLARE vChecker, vExtraMax, vExtraID INT DEFAULT -1; + DECLARE vOldExamType, vChecker, vExtraMax, vExtraID INT DEFAULT -1; + DECLARE EXIT HANDLER FOR SQLEXCEPTION RETURN -1; IF InternalIsMapLocked(pDisciplineID) OR NOT InternalIsTeacherAuthor(pTeacherID, pDisciplineID) @@ -2075,52 +1759,46 @@ BEGIN RETURN -1; END IF; - SELECT disciplines.ExamType - INTO vChecker + # get exam type and extra module ID + SELECT disciplines.ExamType, modules.ID INTO vOldExamType, vExtraID FROM `disciplines` + INNER JOIN `modules` ON modules.Type = 'extra' AND + modules.DisciplineID = pDisciplineID WHERE disciplines.ID = pDisciplineID LIMIT 1; - - # get Extra module id - SELECT modules.ID - INTO vExtraID - FROM `modules` - WHERE modules.Type = 'extra' AND - modules.DisciplineID = pDisciplineID - LIMIT 1; IF vExtraID <= 0 THEN - RETURN -1; + RETURN -1; + END IF; + # check changed change exam type + IF (vOldExamType = pExamType) THEN + RETURN 0; END IF; - IF (vChecker != pExamType) - THEN - IF pExamType = 'exam' THEN - SET vExtraMax = 7; - SET vChecker = GetDisciplineMaxRate(pDisciplineID); - IF vChecker >= 61 THEN - RETURN 1; - END IF; - SET vChecker = AddModuleExam(pTeacherID, pDisciplineID); - - # delete extra module from - DELETE FROM `submodules` - WHERE submodules.OrderNum > 1 AND - submodules.ModuleID = vExtraID; - ELSE - SET vExtraMax = 29; - SET vChecker = DeleteModuleExam(pTeacherID, pDisciplineID); - SET vChecker = AddSubmodule(pTeacherID, vExtraID, vExtraMax, '', NULL, 'LandmarkControl'); + IF pExamType = 'exam' THEN + SET vExtraMax = 7; + SET vChecker = GetDisciplineMaxRate(pDisciplineID); + IF vChecker >= 61 THEN + RETURN 1; END IF; + SET vChecker = AddModuleExam(pTeacherID, pDisciplineID); - UPDATE `disciplines` - SET disciplines.ExamType = ExamType - WHERE disciplines.ID = pDisciplineID; + # delete extra submodules + DELETE FROM `submodules` + WHERE submodules.OrderNum > 1 AND submodules.ModuleID = vExtraID; + ELSE + SET vExtraMax = 29; + SET vChecker = DeleteModuleExam(pTeacherID, pDisciplineID); + SET vChecker = AddSubmodule(pTeacherID, vExtraID, vExtraMax, '', NULL, 'LandmarkControl'); + END IF; - UPDATE `submodules` + UPDATE `disciplines` + SET disciplines.ExamType = pExamType + WHERE disciplines.ID = pDisciplineID + LIMIT 1; + UPDATE `submodules` SET submodules.MaxRate = vExtraMax WHERE submodules.ModuleID = vExtraID; - END IF; RETURN 0; END // @@ -2132,41 +1810,40 @@ CREATE FUNCTION `ChangeDisciplineHours` ) RETURNS int(11) NO SQL BEGIN - IF NOT InternalIsTeacherAuthor(pTeacherID, pDisciplineID) - THEN + IF NOT InternalIsTeacherAuthor(pTeacherID, pDisciplineID) THEN RETURN -1; END IF; CASE pType WHEN 0 THEN UPDATE `disciplines` - SET disciplines.PracticeCount = pHours + SET disciplines.PracticeCount = pHours WHERE disciplines.ID = pDisciplineID LIMIT 1; WHEN 1 THEN UPDATE `disciplines` - SET disciplines.LectureCount = pHours + SET disciplines.LectureCount = pHours WHERE disciplines.ID = pDisciplineID LIMIT 1; WHEN 2 THEN UPDATE `disciplines` - SET disciplines.LabCount = pHours + SET disciplines.LabCount = pHours WHERE disciplines.ID = pDisciplineID LIMIT 1; END CASE; - - RETURN 0; + RETURN ROW_COUNT()-1; END // DROP FUNCTION IF EXISTS BindGroup// CREATE FUNCTION `BindGroup` - ( `pTeacherID` INT, `pDisciplineID` INT, `pGroupID` INT + (`pTeacherID` INT, `pDisciplineID` INT, `pGroupID` INT ) RETURNS int(11) NO SQL BEGIN DECLARE vChecker INT DEFAULT -1; + DECLARE EXIT HANDLER FOR SQLEXCEPTION RETURN -1; # 1. check if AccessedTeacher is author IF NOT InternalIsTeacherAuthor(pTeacherID, pDisciplineID) OR @@ -2176,8 +1853,8 @@ BEGIN END IF; # 2. check if study group is bound to discipline - SELECT disciplines_groups.ID - INTO vChecker + # TODO: extract method + SELECT disciplines_groups.ID INTO vChecker FROM `disciplines_groups` WHERE disciplines_groups.GroupID = pGroupID AND disciplines_groups.DisciplineID = pDisciplineID @@ -2188,19 +1865,18 @@ BEGIN # 3. delete students of this group which were bound to discipline before DELETE FROM `disciplines_students` - WHERE disciplines_students.DisciplineID = pDisciplineID AND - disciplines_students.StudentID IN - ( SELECT students.ID - FROM `students` - WHERE students.GroupID = pGroupID - ); + WHERE disciplines_students.DisciplineID = pDisciplineID AND + disciplines_students.StudentID IN + (SELECT students.ID + FROM `students` + WHERE students.GroupID = pGroupID + ); # 4. bind whole group INSERT INTO `disciplines_groups` (DisciplineID, GroupID) - VALUES (pDisciplineID, pGroupID ); + VALUES (pDisciplineID, pGroupID ); RETURN 0; - END // @@ -2211,50 +1887,39 @@ CREATE FUNCTION `BindStudent` ) RETURNS int(11) NO SQL BEGIN - DECLARE vChecker, vGroupID, vTemp INT DEFAULT -1; + DECLARE vInGroup, vChecker, vGroupID, vTemp INT DEFAULT -1; + DECLARE EXIT HANDLER FOR SQLEXCEPTION RETURN -1; # 1. check if AccessedTeacher is author - IF NOT InternalIsTeacherAuthor(pTeacherID, pDisciplineID) - THEN + IF NOT InternalIsTeacherAuthor(pTeacherID, pDisciplineID) THEN RETURN -1; END IF; # 2. check if student's group is bound yet - SELECT students.GroupID - INTO vGroupID + SELECT disciplines_groups.ID INTO vInGroup FROM `students` + INNER JOIN `disciplines_groups` ON disciplines_groups.DisciplineID = pDisciplineID AND + disciplines_groups.GroupID = students.GroupID WHERE students.ID = pStudentID LIMIT 1; - SELECT disciplines_groups.ID - INTO vChecker - FROM `disciplines_groups` - WHERE disciplines_groups.DisciplineID = pDisciplineID AND - disciplines_groups.GroupID = vGroupID - LIMIT 1; - IF vChecker > 0 THEN + # try to remove detached attribute + IF vInGroup > 0 THEN DELETE FROM `disciplines_students` - WHERE disciplines_students.DisciplineID = pDisciplineID AND + WHERE disciplines_students.DisciplineID = pDisciplineID AND disciplines_students.StudentID = pStudentID - LIMIT 1; + LIMIT 1; RETURN 0; END IF; -# 3. check if student is bound - SELECT disciplines_students.ID - INTO vChecker - FROM `disciplines_students` - WHERE disciplines_students.DisciplineID = pDisciplineID AND - disciplines_students.StudentID = pStudentID - LIMIT 1; - IF vChecker > 0 THEN - RETURN 1; - END IF; - -# 4. bind student + +# 3. try bind student INSERT INTO `disciplines_students` - ( DisciplineID, StudentID, Type) - VALUES ( pDisciplineID, pStudentID, 'attach'); + (DisciplineID, StudentID, Type) + VALUES (pDisciplineID, pStudentID, 'attach') + # update stub/ already bounded + ON DUPLICATE KEY UPDATE + disciplines_students.StudentID = disciplines_students.StudentID; RETURN 0; END // @@ -2267,24 +1932,22 @@ CREATE FUNCTION `UnbindGroup` ) RETURNS int(11) NO SQL BEGIN - IF NOT InternalIsTeacherAuthor(pTeacherID, pDisciplineID) OR - InternalIsMapLocked(pDisciplineID) - THEN + IF NOT InternalIsTeacherAuthor(pTeacherID, pDisciplineID) OR InternalIsMapLocked(pDisciplineID)THEN RETURN -1; END IF; DELETE FROM `disciplines_groups` - WHERE disciplines_groups.DisciplineID = pDisciplineID AND + WHERE disciplines_groups.DisciplineID = pDisciplineID AND disciplines_groups.GroupID = pGroupID LIMIT 1; + # delete attached, and detached (doesn't take disc in any case) DELETE FROM `disciplines_students` - WHERE disciplines_students.DisciplineID = pDisciplineID AND - disciplines_students.StudentID IN - ( SELECT students.ID - FROM `students` - WHERE students.GroupID = pGroupID - ); + WHERE disciplines_students.DisciplineID = pDisciplineID AND + disciplines_students.StudentID IN + (SELECT students.ID + FROM `students` + WHERE students.GroupID = pGroupID); RETURN 0; END // @@ -2292,40 +1955,31 @@ END // DROP FUNCTION IF EXISTS UnbindStudent// CREATE FUNCTION `UnbindStudent` - ( `pTeacherID` INT, `pDisciplineID` INT, `pStudentID` INT + (`pTeacherID` INT, `pDisciplineID` INT, `pStudentID` INT ) RETURNS int(11) NO SQL BEGIN - DECLARE vChecker, vGroupID INT DEFAULT -1; - - SELECT students.GroupID - INTO vGroupID - FROM `students` - WHERE students.ID = pStudentID - LIMIT 1; - IF vGroupID <= 0 OR - NOT InternalIsTeacherAuthor(pTeacherID, pDisciplineID) - THEN + DECLARE vInGroup INT DEFAULT -1; + DECLARE EXIT HANDLER FOR SQLEXCEPTION RETURN -1; + IF NOT InternalIsTeacherAuthor(pTeacherID, pDisciplineID) THEN RETURN -1; END IF; - SELECT disciplines_groups.ID - INTO vChecker - FROM `disciplines_groups` - WHERE disciplines_groups.DisciplineID = pDisciplineID AND - disciplines_groups.GroupID = vGroupID + SELECT disciplines_groups.ID INTO vInGroup + FROM `students` + INNER JOIN `disciplines_groups` ON disciplines_groups.DisciplineID = pDisciplineID AND + disciplines_groups.GroupID = students.GroupID + WHERE students.ID = pStudentID LIMIT 1; - - IF vChecker > 0 THEN + IF vInGroup > 0 THEN INSERT INTO `disciplines_students` (DisciplineID, StudentID, Type) - VALUES ( pDisciplineID, pStudentID, 'detach'); - + VALUES (pDisciplineID, pStudentID, 'detach'); ELSE DELETE FROM `disciplines_students` - WHERE disciplines_students.DisciplineID = pDisciplineID AND - disciplines_students.StudentID = pStudentID + WHERE disciplines_students.DisciplineID = pDisciplineID AND + disciplines_students.StudentID = pStudentID LIMIT 1; END IF; RETURN 0; @@ -2334,35 +1988,21 @@ END // DROP FUNCTION IF EXISTS BindTeacher// -CREATE FUNCTION `BindTeacher`( `TeacherID` INT, - `BindingTeacherID` INT, - `DisciplineID` INT - ) RETURNS int(11) +CREATE FUNCTION `BindTeacher` + (`pTeacherID` INT, `pBindingTeacherID` INT, `pDisciplineID` INT + ) RETURNS int(11) NO SQL -BEGIN - DECLARE vChecker boolean; - -# 1. check if AccessedTeacher is author - SET vChecker = FALSE; - SELECT (TeacherID = disciplines.AuthorID) - INTO vChecker - FROM `disciplines` - WHERE DisciplineID = disciplines.ID - LIMIT 1; - IF NOT vChecker THEN +BEGIN + IF NOT InternalIsTeacherAuthor(pTeacherID, pDisciplineID) THEN RETURN -1; END IF; -# 2. check if BindingTeacher has rights to access this discipline - IF InternalIsTeacherBinded(BindingTeacherID,DisciplineID) - THEN - RETURN 1; - END IF; - -# 3. insert BindingTeacher in access list + # try to insert BindingTeacher in access list INSERT INTO `disciplines_teachers` - ( DisciplineID, TeacherID) - VALUES ( DisciplineID, BindingTeacherID ); + (DisciplineID, TeacherID) + VALUES (pDisciplineID, pBindingTeacherID) + ON DUPLICATE KEY UPDATE # just stub + disciplines_teachers.TeacherID = disciplines_teachers.TeacherID; RETURN 0; END // @@ -2374,18 +2014,9 @@ CREATE FUNCTION `UnbindTeacher` ) RETURNS int(11) NO SQL BEGIN - DECLARE vChecker boolean DEFAULT FALSE; - - IF pAuthorID = pBindingTeacher THEN - RETURN -1; - END IF; - - SELECT (disciplines.AuthorID = pAuthorID) - INTO vChecker - FROM `disciplines` - WHERE disciplines.ID = pDisciplineID - LIMIT 1; - IF NOT vChecker THEN + IF pAuthorID = pBindingTeacher OR + NOT InternalIsTeacherAuthor(pBindingTeacher, pDisciplineID) + THEN RETURN -1; END IF; @@ -2403,31 +2034,20 @@ CREATE FUNCTION `DelegateDiscipline` ) RETURNS int(11) NO SQL BEGIN - DECLARE vChecker boolean DEFAULT FALSE; + DECLARE EXIT HANDLER FOR SQLEXCEPTION RETURN -1; IF pAuthorID = pNewAuthorID OR - NOT InternalIsTeacherAuthor(pAuthorID, pDisciplineID) + NOT InternalIsTeacherAuthor(pAuthorID, pDisciplineID) OR + NOT InternalIsTeacherBinded(pNewAuthorID, pDisciplineID) THEN RETURN -1; END IF; - SELECT (AuthorID = disciplines.AuthorID) - INTO vChecker - FROM `disciplines` - INNER JOIN `disciplines_teachers` ON disciplines_teachers.DisciplineID = pDisciplineID AND - disciplines_teachers.TeacherID = pNewAuthorID - WHERE DisciplineID = disciplines.ID AND - disciplines.AuthorID = pAuthorID - LIMIT 1; - IF NOT vChecker THEN - RETURN -1; - END IF; - UPDATE `disciplines` SET disciplines.AuthorID = pNewAuthorID WHERE disciplines.ID = pDisciplineID LIMIT 1; - RETURN 0; + RETURN ROW_COUNT()-1; END // @@ -2438,32 +2058,28 @@ CREATE FUNCTION `ClearDiscipline` ) RETURNS int(11) NO SQL BEGIN - IF NOT InternalIsTeacherAuthor(pAuthorID, pDisciplineID) THEN + IF NOT InternalIsTeacherAuthor(pAuthorID, pDisciplineID) THEN RETURN -1; END IF; DELETE FROM `logs_rating` WHERE logs_rating.SubModuleID IN - (SELECT submodules.ID - FROM `submodules` - INNER JOIN `modules` ON submodules.ModuleID = modules.ID - WHERE modules.DisciplineID = pDisciplineID - ); + (SELECT view_roadmap.SubmoduleID + FROM `view_roadmap` + WHERE view_roadmap.DisciplineID = pDisciplineID); DELETE FROM `rating_table` WHERE rating_table.SubModuleID IN - (SELECT submodules.ID - FROM `submodules` - INNER JOIN `modules` ON submodules.ModuleID = modules.ID - WHERE modules.DisciplineID = pDisciplineID - ); + (SELECT view_roadmap.SubmoduleID + FROM `view_roadmap` + WHERE view_roadmap.DisciplineID = pDisciplineID); UPDATE `disciplines` SET disciplines.IsLocked = 0 WHERE disciplines.ID = pDisciplineID LIMIT 1; - RETURN 0; + RETURN ROW_COUNT()-1; END // @@ -2474,17 +2090,15 @@ CREATE FUNCTION `DeleteDiscipline` ) RETURNS int(11) NO SQL BEGIN - DECLARE vTemp INT; - IF NOT InternalIsTeacherAuthor(pAuthorID, pDisciplineID) THEN + DECLARE vTemp INT DEFAULT -1; + IF NOT InternalIsTeacherAuthor(pAuthorID, pDisciplineID) THEN RETURN -1; END IF; - SELECT disciplines.IsLocked - INTO vTemp + SELECT disciplines.IsLocked INTO vTemp FROM `disciplines` WHERE disciplines.ID = pDisciplineID LIMIT 1; - IF vTemp != 0 THEN RETURN -1; END IF; @@ -2494,23 +2108,8 @@ BEGIN RETURN -1; END IF; + # TODO: ClearDiscipline if need - DELETE FROM `logs_rating` - WHERE logs_rating.SubModuleID IN - ( - SELECT submodules.ID - FROM `submodules` - INNER JOIN `modules` ON submodules.ModuleID = modules.ID - WHERE modules.DisciplineID = pDisciplineID - ); - - DELETE FROM `rating_table` - WHERE rating_table.SubModuleID IN - (SELECT submodules.ID - FROM `submodules` - INNER JOIN `modules` ON submodules.ModuleID = modules.ID - WHERE modules.DisciplineID = pDisciplineID - ); DELETE FROM `submodules` WHERE submodules.ModuleID IN @@ -2570,14 +2169,12 @@ CREATE FUNCTION `RestrictAfterMilestone` ( `pTeacherID` INT, `pDisciplineID` INT ) RETURNS int(11) NO SQL -BEGIN - +BEGIN UPDATE `disciplines` SET disciplines.MilestoneDate = CURDATE(), disciplines.isMilestone = 1 WHERE disciplines.ID = pDisciplineID LIMIT 1; - RETURN 0; END // @@ -2594,7 +2191,6 @@ BEGIN WHERE disciplines.SemesterID = @CurrentSemesterID AND disciplines.ExamType = 'credit' AND disciplines.FacultyID= pFacultyID; - RETURN 0; END // @@ -2612,9 +2208,9 @@ CREATE FUNCTION `ChangeModuleName` NO SQL BEGIN DECLARE vDisciplineID INT DEFAULT -1; + DECLARE EXIT HANDLER FOR SQLEXCEPTION RETURN -1; - SELECT disciplines.ID - INTO vDisciplineID + SELECT disciplines.ID INTO vDisciplineID FROM `modules` INNER JOIN `disciplines` ON disciplines.ID = modules.DisciplineID AND disciplines.AuthorID = pTeacherID @@ -2631,7 +2227,7 @@ BEGIN SET modules.Name = pName WHERE modules.ID = pModuleID LIMIT 1; - RETURN 0; + RETURN ROW_COUNT()-1; END // @@ -2644,6 +2240,7 @@ CREATE FUNCTION `AddModule` NO SQL BEGIN DECLARE vChecker INT DEFAULT 0; + DECLARE EXIT HANDLER FOR SQLEXCEPTION RETURN -1; IF NOT InternalIsTeacherAuthor(pTeacherID, pDisciplineID) OR InternalIsMapLocked(pDisciplineID) @@ -2651,35 +2248,22 @@ BEGIN RETURN -1; END IF; - SELECT MAX(modules.OrderNum) - INTO vChecker + SELECT MAX(modules.OrderNum)+1 INTO vChecker FROM `modules` - WHERE modules.DisciplineID = pDisciplineID AND - modules.Type = 'regular' + WHERE modules.DisciplineID = pDisciplineID AND modules.Type = 'regular' LIMIT 1; - IF vChecker is NULL THEN - SET vChecker = 0; - END IF; - SET vChecker = vChecker + 1; INSERT INTO `modules` (Name, OrderNum, DisciplineID ) - VALUES (Name , vChecker , pDisciplineID ); - - - RETURN (SELECT modules.ID - FROM `modules` - WHERE modules.DisciplineID = pDisciplineID AND - vChecker = modules.OrderNum - LIMIT 1 - ); + VALUES (pName, vChecker, pDisciplineID); + RETURN LAST_INSERT_ID(); END // DROP FUNCTION IF EXISTS AddModuleExam// CREATE FUNCTION `AddModuleExam` - ( `pTeacherID` INT, `pDisciplineID` INT + (`pTeacherID` INT, `pDisciplineID` INT ) RETURNS int(11) NO SQL BEGIN @@ -2700,19 +2284,10 @@ BEGIN END IF; INSERT INTO `modules` - ( Name, OrderNum, DisciplineID, Type ) - VALUES ( 'Ðкзамен' , 3141692 , pDisciplineID, 2 ); - - SELECT modules.ID - INTO vModule - FROM `modules` - WHERE modules.DisciplineID = pDisciplineID AND - modules.Type = 'exam' - LIMIT 1; - IF vModule <= 0 THEN - RETURN -1; - END IF; + (Name, OrderNum, DisciplineID, Type) + VALUES ('Ðкзамен' , 3141692 , pDisciplineID, 'exam'); + SET vModule = LAST_INSERT_ID(); SET vChecker = AddSubmodule(pTeacherID, vModule, 40, '', NULL, 'LandmarkControl'); SET vChecker = AddSubmodule(pTeacherID, vModule, 40, '', NULL, 'LandmarkControl'); SET vChecker = AddSubmodule(pTeacherID, vModule, 40, '', NULL, 'LandmarkControl'); @@ -2732,19 +2307,17 @@ BEGIN RETURN -1; END IF; - SELECT modules.ID - INTO vChecker + SELECT modules.ID INTO vChecker FROM `modules` - WHERE modules.DisciplineID = pDisciplineID AND - modules.Type = 'extra' + WHERE modules.DisciplineID = pDisciplineID AND modules.Type = 'extra' LIMIT 1; IF vChecker > 0 THEN RETURN -2; END IF; INSERT INTO `modules` - (Name, OrderNum, DisciplineID, Type) - VALUES ('Добор баллов' , 2900666 , pDisciplineID, 'extra'); + (Name, OrderNum, DisciplineID, Type) + VALUES ('Добор баллов' , 2900666 , pDisciplineID, 'extra'); SELECT modules.ID, disciplines.ExamType diff --git a/db/Views.sql b/db/Views.sql index 037093a55..9ca560966 100644 --- a/db/Views.sql +++ b/db/Views.sql @@ -1,7 +1,7 @@ -CREATE OR REPLACE VIEW `view_study_groups` AS +CREATE OR REPLACE VIEW `view_groups` AS SELECT study_groups.ID AS 'GroupID', study_groups.GroupNum AS 'GroupNum', study_groups.Name AS 'GroupName', @@ -45,9 +45,9 @@ CREATE OR REPLACE VIEW `view_students` AS students.FirstName, students.SecondName, students.AccountID, - view_study_groups.* + view_groups.* FROM `students` - INNER JOIN `view_study_groups` ON view_study_groups.GroupID = students.GroupID; + INNER JOIN `view_groups` ON view_groups.GroupID = students.GroupID; CREATE OR REPLACE VIEW `view_disciplines` AS diff --git a/db/fix.sql b/db/fix.sql index 72c64cdd3..a6602e303 100644 --- a/db/fix.sql +++ b/db/fix.sql @@ -23,3 +23,12 @@ ALTER TABLE `students` ADD CONSTRAINT `students_ibfk_1` FOREIGN KEY (`GroupID`) REFERENCES `study_groups` (`ID`); +ALTER TABLE `page_access` +CHANGE `Pagename` `Pagename` VARCHAR( 150 ) CHARACTER SET utf8 COLLATE utf8_general_ci NOT NULL ; + +ALTER TABLE `page_access` ADD UNIQUE (`Pagename`); + +ALTER TABLE `accounts` ADD UNIQUE (`ActivationCode`); + + + -- GitLab