diff --git a/db/StoredProcedures.sql b/db/StoredProcedures.sql index fb35d4580f8b5587811bb790e571261622180dbe..298476cb3f3c8091316a786e5dc61c4d9830df2d 100644 --- a/db/StoredProcedures.sql +++ b/db/StoredProcedures.sql @@ -37,8 +37,9 @@ DROP PROCEDURE IF EXISTS GetReports// # ------------------------------------------------------------------------------------------- DROP PROCEDURE IF EXISTS GetSettings// -CREATE PROCEDURE `GetSettings`(IN `pKey` VARCHAR(50) CHARSET utf8) - NO SQL +CREATE PROCEDURE `GetSettings` ( + IN `pKey` VARCHAR(50) CHARSET utf8 +) NO SQL BEGIN SELECT general_settings.* FROM `general_settings` @@ -52,8 +53,9 @@ END // # ------------------------------------------------------------------------------------------- DROP PROCEDURE IF EXISTS GetSemesterInfo// -CREATE PROCEDURE `GetSemesterInfo` (IN `pSemesterID` INT) - NO SQL +CREATE PROCEDURE `GetSemesterInfo` ( + IN `pSemesterID` INT +) NO SQL BEGIN SELECT semesters.Num As 'Num', semesters.Year As 'Year' @@ -63,8 +65,8 @@ BEGIN END // DROP PROCEDURE IF EXISTS GetSemesters// -CREATE PROCEDURE `GetSemesters` () - NO SQL +CREATE PROCEDURE `GetSemesters` ( +) NO SQL BEGIN SELECT semesters.ID, semesters.Year, @@ -80,8 +82,8 @@ END // # ------------------------------------------------------------------------------------------- DROP PROCEDURE IF EXISTS GetFaculties// -CREATE PROCEDURE `GetFaculties` ( ) - NO SQL +CREATE PROCEDURE `GetFaculties` ( +) NO SQL BEGIN SELECT faculties.ID, faculties.Name, @@ -95,8 +97,9 @@ END // # ------------------------------------------------------------------------------------------- DROP PROCEDURE IF EXISTS GetDepartments// -CREATE PROCEDURE `GetDepartments` (IN `pFacultyID` INT) - NO SQL +CREATE PROCEDURE `GetDepartments` ( + IN `pFacultyID` INT +) NO SQL BEGIN SELECT departments.ID, departments.Name @@ -111,8 +114,9 @@ END // # ------------------------------------------------------------------------------------------- DROP PROCEDURE IF EXISTS GetSpecializations// -CREATE PROCEDURE `GetSpecializations` (IN `pFacultyID` INT) - NO SQL +CREATE PROCEDURE `GetSpecializations` ( + IN `pFacultyID` INT +) NO SQL BEGIN SELECT specializations.ID, specializations.Name, @@ -128,8 +132,8 @@ END // # ------------------------------------------------------------------------------------------- DROP PROCEDURE IF EXISTS GetJobPositions// -CREATE PROCEDURE `GetJobPositions` ( ) - NO SQL +CREATE PROCEDURE `GetJobPositions` ( +) NO SQL BEGIN SELECT job_positions.ID, job_positions.Name @@ -143,13 +147,13 @@ END // # ------------------------------------------------------------------------------------------- DROP PROCEDURE IF EXISTS GetGrades// -CREATE PROCEDURE `GetGrades` ( ) - NO SQL +CREATE PROCEDURE `GetGrades` ( +) NO SQL BEGIN - SELECT grades.ID AS 'ID', - grades.Num AS 'Num', - grades.Degree AS 'Degree' - FROM `grades` + SELECT grades.ID, + grades.Num, + grades.Degree + FROM `grades` ORDER BY grades.ID; END // @@ -159,9 +163,10 @@ END // # ------------------------------------------------------------------------------------------- DROP PROCEDURE IF EXISTS GetGroups// -CREATE PROCEDURE `GetGroups` - (IN `pGradeID` INT, IN `pFacultyID` INT) - NO SQL +CREATE PROCEDURE `GetGroups` ( + IN `pGradeID` INT, + IN `pFacultyID` INT +) NO SQL BEGIN SELECT view_groups.GroupID AS 'ID', view_groups.GroupNum, @@ -177,8 +182,9 @@ END // # get all general study groups, that takes this course DROP PROCEDURE IF EXISTS GetGroupsForDiscipline// -CREATE PROCEDURE `GetGroupsForDiscipline` (IN `pDisciplineID` INT) - NO SQL +CREATE PROCEDURE `GetGroupsForDiscipline` ( + IN `pDisciplineID` INT +) NO SQL BEGIN SELECT view_groups.GroupID AS 'ID', view_groups.GroupNum, @@ -201,15 +207,16 @@ END // # ------------------------------------------------------------------------------------------- DROP PROCEDURE IF EXISTS GetSubjects// -CREATE PROCEDURE `GetSubjects` (IN `pFacultyID` INT) - NO SQL +CREATE PROCEDURE `GetSubjects` ( + IN `pFacultyID` INT +) NO SQL BEGIN SELECT subjects.ID, subjects.Name, subjects.Abbr FROM `subjects_faculties` INNER JOIN `subjects` ON subjects_faculties.SubjectID = subjects.ID - WHERE subjects_faculties.FacultyID = pFacultyID + WHERE subjects_faculties.FacultyID = pFacultyID ORDER BY subjects.Name ASC; END // @@ -219,6 +226,7 @@ END // # Label: accounts # ------------------------------------------------------------------------------------------- +# TODO: deprecated DROP PROCEDURE IF EXISTS GetAccountInfo// CREATE PROCEDURE `GetAccountInfo` ( IN `pUserID` INT ) NO SQL @@ -238,13 +246,12 @@ BEGIN LIMIT 1; END // - +# TODO: deprecated DROP PROCEDURE IF EXISTS GetPersonalInfo// CREATE PROCEDURE `GetPersonalInfo` ( - IN `pUserID` INT, - IN `pSemesterID` INT - ) - NO SQL + IN `pUserID` INT, + IN `pSemesterID` INT +) NO SQL BEGIN DECLARE vAccountType INT DEFAULT -1; SELECT user_roles.Type INTO vAccountType @@ -293,6 +300,85 @@ BEGIN END IF; END // +DROP PROCEDURE IF EXISTS GetFullInfo// +CREATE PROCEDURE `GetFullInfo` ( + IN `pUserID` INT, + IN `pSemesterID` INT +) NO SQL +BEGIN + DECLARE vAccountType enum('student', 'teacher') DEFAULT -1; + + 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 # student info + view_students.LastName, + view_students.FirstName, + view_students.SecondName, + view_students.StudentID, + view_students.GradeID, + view_students.GradeNum, + view_students.GroupID, + view_students.GroupNum, + view_students.GroupName, + view_students.Degree, + view_students.SpecID, + view_students.SpecName, + view_students.SpecAbbr, + view_students.FacultyID, + view_students.FacultyName, + view_students.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_students` + INNER JOIN `accounts` ON accounts.ID = view_students.AccountID + INNER JOIN `user_roles` ON user_roles.ID = accounts.UserRoleID + WHERE view_students.AccountID = pUserID AND + view_students.SemesterID = pSemesterID + 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 // @@ -300,6 +386,7 @@ END // # Label: teachers # ------------------------------------------------------------------------------------------- +# TODO: used in php DROP PROCEDURE IF EXISTS GetTeachersByFaculty// # CREATE PROCEDURE `GetTeachersByFaculty` (IN `pFacultyID` INT) # NO SQL @@ -342,40 +429,48 @@ DROP PROCEDURE IF EXISTS GetTeachersForDiscipline// CREATE PROCEDURE `GetTeachersForDiscipline`(IN `pDisciplineID` INT) NO SQL BEGIN - SELECT view_disciplines_teachers.TeacherID AS 'ID', - view_disciplines_teachers.LastName, - view_disciplines_teachers.FirstName, - view_disciplines_teachers.SecondName, - view_disciplines_teachers.JobPositionID, - view_disciplines_teachers.JobPositionName, - view_disciplines_teachers.DepID, - view_disciplines_teachers.DepName, - view_disciplines_teachers.FacultyID, - view_disciplines_teachers.FacultyAbbr, - view_disciplines_teachers.IsAuthor - FROM `view_disciplines_teachers` - WHERE view_disciplines_teachers.DisciplineID = pDisciplineID - ORDER BY view_disciplines_teachers.IsAuthor DESC, - view_disciplines_teachers.LastName ASC, - view_disciplines_teachers.FirstName ASC; + 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 // # get teachers, that don't teach course DROP PROCEDURE IF EXISTS SearchTeachers// -CREATE PROCEDURE `SearchTeachers` - ( IN `pFacultyID` INT, IN `pDepartmentID` INT, - IN `pFullName` VARCHAR(100) CHARSET utf8, - # order: LastName + FirstName + SecondName - IN `pDisciplineID` INT ) - NO SQL +CREATE PROCEDURE `SearchTeachers` ( + IN `pFacultyID` INT, + IN `pDepartmentID` INT, + IN `pFullName` VARCHAR(100) CHARSET utf8, + # order: LastName + FirstName + SecondName + IN `pDisciplineID` INT +) NO SQL BEGIN DECLARE vAuthorID INT DEFAULT -1; - SELECT disciplines.AuthorID INTO vAuthorID - FROM `disciplines` - WHERE disciplines.ID = pDisciplineID - LIMIT 1; + SET vAuthorID = GetDisciplineProperty(pDisciplineID, 'author'); + + CREATE TEMPORARY TABLE IF NOT EXISTS tDiscTeachers AS ( + SELECT disciplines_teachers.TeacherID + FROM disciplines_teachers + WHERE disciplines_teachers.DisciplineID = pDisciplineID + ); SELECT view_teachers.TeacherID AS 'ID', view_teachers.LastName, @@ -384,14 +479,21 @@ BEGIN view_teachers.JobPositionName, view_teachers.DepID, view_teachers.DepName, - (view_teachers.TeacherID = vAuthorID) AS 'IsAuthor' + ( view_teachers.TeacherID = vAuthorID ) AS 'IsAuthor' FROM `view_teachers` - WHERE NOT InternalIsTeacherBounded(view_teachers.TeacherID, pDisciplineID) AND - view_teachers.FacultyID = pFacultyID AND - CONCAT( view_teachers.LastName, view_teachers.FirstName, view_teachers.SecondName) - LIKE CONCAT('%', pFullName, '%') - ORDER BY view_teachers.FacultyID ASC,view_teachers.DepName ASC, - view_teachers.LastName ASC, view_teachers.FirstName ASC; + WHERE view_teachers.FacultyID = pFacultyID AND + ( pDepartmentID = 0 OR view_teachers.DepID = pDepartmentID ) AND + NOT EXISTS ( + SELECT * FROM tDiscTeachers + WHERE tDiscTeachers.TeacherID = view_teachers.TeacherID + LIMIT 1 + ) AND + CONCAT( view_teachers.LastName, ' ', view_teachers.FirstName, ' ', view_teachers.SecondName) + LIKE CONCAT('%', pFullName, '%') + ORDER BY view_teachers.FacultyID ASC, + view_teachers.DepName ASC, + view_teachers.LastName ASC, + view_teachers.FirstName ASC; END // diff --git a/db/Views.sql b/db/Views.sql index b13e7570d42b53d2f1ee61252927b1c3c1e238d2..051cad6e7d3cd51c77d8a74c119853e97bfdc4f5 100644 --- a/db/Views.sql +++ b/db/Views.sql @@ -1,5 +1,9 @@ +DROP VIEW IF EXISTS view_disciplines_teachers; + + + CREATE OR REPLACE VIEW `view_groups` AS SELECT study_groups.ID AS 'GroupID', @@ -79,49 +83,31 @@ CREATE OR REPLACE VIEW `view_disciplines` AS INNER JOIN `grades` ON grades.ID = disciplines.GradeID; -CREATE OR REPLACE VIEW `view_disciplines_results` AS - SELECT disciplines.ID AS 'DisciplineID', - SUM(submodules.MaxRate) AS 'DisciplineRateMax', - SUM(submodules.MaxRate*submodules.IsUsed) AS 'DisciplineRateCur' - FROM `submodules` - INNER JOIN `modules` ON modules.ID = submodules.ModuleID - RIGHT JOIN `disciplines` ON disciplines.ID = modules.DisciplineID - WHERE (modules.Type = 'regular') OR (modules.Type = 'exam' AND submodules.OrderNum = 1) - GROUP BY disciplines.ID; - - -CREATE OR REPLACE VIEW `view_disciplines_teachers` AS - SELECT view_disciplines.DisciplineID, - view_teachers.*, - (view_disciplines.AuthorID = view_teachers.TeacherID) AS 'IsAuthor' - FROM `view_disciplines` - LEFT JOIN `disciplines_teachers` ON disciplines_teachers.DisciplineID = view_disciplines.DisciplineID - INNER JOIN `view_teachers` ON view_teachers.TeacherID = disciplines_teachers.TeacherID; -CREATE OR REPLACE VIEW `view_disciplines_students` AS - (SELECT disciplines_students.DisciplineID, +CREATE OR REPLACE VIEW `view_disciplines_students` AS ( + SELECT disciplines_students.DisciplineID, disciplines_students.Type AS 'AttachType', view_students.* FROM `disciplines` LEFT JOIN `disciplines_students` ON disciplines_students.DisciplineID = disciplines.ID INNER JOIN `view_students` ON view_students.StudentID = disciplines_students.StudentID AND view_students.SemesterID = disciplines.SemesterID - ) UNION - (SELECT disciplines_groups.DisciplineID, +) UNION ( + SELECT disciplines_groups.DisciplineID, NULL AS 'AttachType', view_students.* FROM `disciplines` LEFT JOIN `disciplines_groups` ON disciplines_groups.DisciplineID = disciplines.ID LEFT JOIN `view_students` ON view_students.GroupID = disciplines_groups.GroupID AND view_students.SemesterID = disciplines.SemesterID - WHERE NOT EXISTS - (SELECT disciplines_students.StudentID + WHERE NOT EXISTS ( + SELECT disciplines_students.StudentID FROM `disciplines_students` WHERE disciplines_students.DisciplineID = disciplines_groups.DisciplineID AND disciplines_students.StudentID = view_students.StudentID ) - ); +); CREATE OR REPLACE VIEW `view_roadmap` AS @@ -129,19 +115,31 @@ CREATE OR REPLACE VIEW `view_roadmap` AS modules.ID AS 'ModuleID', modules.Name AS 'ModuleName', modules.OrderNum AS 'ModuleOrderNum', - modules.Type AS 'ModuleType', - # enum('regular','exam', 'bonus', 'extra') + modules.Type AS 'ModuleType', # enum('regular','exam', 'bonus', 'extra') submodules.ID AS 'SubmoduleID', submodules.Name AS 'SubmoduleName', submodules.OrderNum AS 'SubmoduleOrderNum', submodules.MaxRate AS 'SubmoduleRate', - submodules.Type AS 'SubmoduleType', - # enum('CurrentControl','LandmarkControl') + submodules.Type AS 'SubmoduleType', # enum('CurrentControl','LandmarkControl') submodules.IsUsed AS 'SubmoduleIsUsed' FROM `modules` LEFT JOIN `submodules` ON submodules.ModuleID = modules.ID; +CREATE OR REPLACE VIEW `view_disciplines_results` AS + SELECT disciplines.ID AS 'DisciplineID', + SUM(submodules.MaxRate) AS 'DisciplineRateMax', + SUM(submodules.MaxRate*submodules.IsUsed) AS 'DisciplineRateCur' + FROM `disciplines` + LEFT JOIN `modules` ON modules.DisciplineID = disciplines.ID + LEFT JOIN `submodules` ON submodules.ModuleID = modules.ID + WHERE modules.Type = 'regular' OR + (modules.Type = 'exam' AND submodules.OrderNum = 1) + GROUP BY disciplines.ID; + + + + # without students, that haven't any rate CREATE OR REPLACE VIEW `view_rating_result` AS SELECT rating_table.StudentID,