Skip to content
Snippets Groups Projects
StoredFunctions.sql 66.6 KiB
Newer Older
PavelBegunkov's avatar
PavelBegunkov committed
DELIMITER //

DROP FUNCTION IF EXISTS GetGradeID//
DROP FUNCTION IF EXISTS SetCurSemesterID//
DROP FUNCTION IF EXISTS SetHashKey//

drop function if exists InternalIsTeacherBinded//
DROP FUNCTION IF EXISTS GetSemesterID//

PavelBegunkov's avatar
PavelBegunkov committed
DROP FUNCTION IF EXISTS GetRateForDiscExtra//
DROP FUNCTION IF EXISTS GetRateForDiscBonus//
DROP FUNCTION IF EXISTS GetRateForDiscSemester//
DROP FUNCTION IF EXISTS GetRateForDiscExamNum//
DROP FUNCTION IF EXISTS GetRateForDiscExam//
DROP FUNCTION IF EXISTS InternalNotify//
DROP FUNCTION IF EXISTS GetDisciplineMaxRate//
DROP FUNCTION IF EXISTS OrderModuleTypesForSession//

DROP FUNCTION IF EXISTS CreateStudyGroup//

DROP FUNCTION IF EXISTS GetAccCountByCode//
DROP FUNCTION IF EXISTS GetAccCountByMail//
DROP FUNCTION IF EXISTS GetAccCountByLogin//

DROP FUNCTION IF EXISTS ChangePassword//
DROP FUNCTION IF EXISTS ChangeLogin//
DROP FUNCTION IF EXISTS ChangeMail//

DROP FUNCTION IF EXISTS GetRateForDisc//

drop function if exists InternalIsTeacherBounded//
DROP FUNCTION IF EXISTS SetSemesterID//
DROP FUNCTION IF EXISTS AddDiscipline//

DROP FUNCTION IF EXISTS GetMaxRateForDisc//

DROP FUNCTION IF EXISTS BindTeacher//

PavelBegunkov's avatar
PavelBegunkov committed
DROP FUNCTION IF EXISTS GetDisciplineSemesterID//

DROP FUNCTION IF EXISTS SetBitmaskByPagename//
DROP FUNCTION IF EXISTS GetBitmaskByPagename//
DROP FUNCTION IF EXISTS SetSettings//
PavelBegunkov's avatar
PavelBegunkov committed
# -------------------------------------------------------------------------------------------
# Label: abbreviations
# -------------------------------------------------------------------------------------------

# abbreviation: abbr
# specialization: spec
# department: dep

# -------------------------------------------------------------------------------------------
# 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
PavelBegunkov's avatar
PavelBegunkov committed
    NO SQL
BEGIN
    DECLARE vChecker BOOLEAN DEFAULT FALSE;

xamgore's avatar
xamgore committed
    SELECT disciplines.IsLocked INTO vChecker
        FROM `disciplines`
        WHERE disciplines.ID = pDisciplineID
        LIMIT 1;

    RETURN vChecker;
PavelBegunkov's avatar
PavelBegunkov committed
END //


# check, that student really take this course
DROP FUNCTION IF EXISTS InternalIsStudentAttached//
CREATE FUNCTION `InternalIsStudentAttached` (
    `pStudentID` INT,
    `pDisciplineID` INT,
    `pSemesterID` INT
) RETURNS BOOLEAN
PavelBegunkov's avatar
PavelBegunkov committed
    NO SQL
BEGIN
    DECLARE vAttachType enum('attach','detach') DEFAULT NULL;
    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;
    RETURN EXISTS(
        SELECT * FROM `students_groups`
        INNER JOIN `disciplines_groups` ON  disciplines_groups.DisciplineID = pDisciplineID AND
                                            disciplines_groups.GroupID = students_groups.GroupID
        WHERE   students_groups.StudentID = pStudentID AND
                students_groups.SemesterID = pSemesterID
        LIMIT 1
    );
PavelBegunkov's avatar
PavelBegunkov committed
# check, that teacher teach this course
DROP FUNCTION IF EXISTS InternalIsTeacherBound//
CREATE FUNCTION InternalIsTeacherBound (
        `pTeacherID` INT,
        `pDisciplineID` INT
    ) RETURNS BOOLEAN
PavelBegunkov's avatar
PavelBegunkov committed
    NO SQL
BEGIN
    RETURN EXISTS (
        SELECT * FROM `disciplines_teachers`
            WHERE   disciplines_teachers.TeacherID = pTeacherID AND
                    disciplines_teachers.DisciplineID = pDisciplineID
            LIMIT 1
    );
PavelBegunkov's avatar
PavelBegunkov committed
END //


DROP FUNCTION IF EXISTS InternalIsTeacherAuthor//
CREATE FUNCTION `InternalIsTeacherAuthor` (
        `pTeacherID` INT,
        `pDisciplineID` INT
    ) RETURNS BOOLEAN
PavelBegunkov's avatar
PavelBegunkov committed
    NO SQL
BEGIN
    DECLARE vAuthorID INT DEFAULT -1;
    SELECT disciplines.AuthorID INTO vAuthorID
        FROM `disciplines`
        WHERE disciplines.ID = pDisciplineID
PavelBegunkov's avatar
PavelBegunkov committed
        LIMIT 1;

    RETURN ( vAuthorID = 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;
# check, regular + exam rate == 100
PavelBegunkov's avatar
PavelBegunkov committed
DROP FUNCTION IF EXISTS InternalIsMapCreated//
CREATE FUNCTION `InternalIsMapCreated` (
        `pDisciplineID` INT
    ) RETURNS int(11)
PavelBegunkov's avatar
PavelBegunkov committed
    NO SQL
BEGIN
    DECLARE vMaxRate INT DEFAULT -1;

    SELECT view_disciplines_results.DisciplineRateMax INTO vMaxRate
        FROM `view_disciplines_results`
        WHERE view_disciplines_results.DisciplineID = pDisciplineID
        LIMIT 1;

    RETURN ( vMaxRate = 100 );
PavelBegunkov's avatar
PavelBegunkov committed
END //

# ordering helper
PavelBegunkov's avatar
PavelBegunkov committed
DROP FUNCTION IF EXISTS InternalOrderModuleTypesForSession//
CREATE FUNCTION `InternalOrderModuleTypesForSession` (
        `pModuleType` INT
    ) RETURNS INT(3)
PavelBegunkov's avatar
PavelBegunkov committed
    NO SQL
BEGIN
    DECLARE vRes INT DEFAULT 0;
PavelBegunkov's avatar
PavelBegunkov committed
    CASE pModuleType
        WHEN 4 THEN SET vRes = 1; # extra
        WHEN 2 THEN SET vRes = 2; # exam
        WHEN 3 THEN SET vRes = 3; # bonus
        ELSE SET vRes = 4;
PavelBegunkov's avatar
PavelBegunkov committed
    END CASE;
PavelBegunkov's avatar
PavelBegunkov committed
    RETURN vRes;
END //
PavelBegunkov's avatar
PavelBegunkov committed




# -------------------------------------------------------------------------------------------
# Label: preferences
# Label: magic
# -------------------------------------------------------------------------------------------

# set values of record with key \pKey,
# if doesn't exist, then create.
PavelBegunkov's avatar
PavelBegunkov committed



# -------------------------------------------------------------------------------------------
# Label: semesters
# -------------------------------------------------------------------------------------------

PavelBegunkov's avatar
PavelBegunkov committed
DROP FUNCTION IF EXISTS GetDisciplineProperty//
CREATE FUNCTION `GetDisciplineProperty` (
    `pDisciplineID` INT,
    `pType` enum('grade', 'subject', 'author', 'semester', 'milestone', 'type')
) RETURNS int(11)
    NO SQL
BEGIN
PavelBegunkov's avatar
PavelBegunkov committed
    DECLARE vRes INT DEFAULT -1;

    SELECT CASE pType
            WHEN 'semester' THEN disciplines.SemesterID
            WHEN 'author' THEN disciplines.AuthorID
PavelBegunkov's avatar
PavelBegunkov committed
            WHEN 'grade' THEN disciplines.GradeID
            WHEN 'subject' THEN disciplines.SubjectID
            WHEN 'milestone' THEN disciplines.Milestone
            WHEN 'type' THEN disciplines.ExamType + 0
        END
        INTO vRes
PavelBegunkov's avatar
PavelBegunkov committed
        FROM `disciplines`
        WHERE disciplines.ID = pDisciplineID
        LIMIT 1;
PavelBegunkov's avatar
PavelBegunkov committed
    RETURN vRes;
END //
PavelBegunkov's avatar
PavelBegunkov committed
# -------------------------------------------------------------------------------------------
# Label: faculties
# -------------------------------------------------------------------------------------------

DROP FUNCTION IF EXISTS CreateFaculty //
CREATE FUNCTION CreateFaculty (
        `pFacultyName` TEXT CHARSET utf8,
        `pFacultyAbbr` TEXT CHARSET utf8
    ) RETURNS INT(11) # -1 or id
PavelBegunkov's avatar
PavelBegunkov committed
    NO SQL
BEGIN
    DECLARE EXIT HANDLER FOR SQLEXCEPTION RETURN -1;

    INSERT INTO faculties
        (Name, Abbr) VALUES(pFacultyName, pFacultyAbbr);
    RETURN LAST_INSERT_ID();
PavelBegunkov's avatar
PavelBegunkov committed

# -------------------------------------------------------------------------------------------
# Label: departments
# -------------------------------------------------------------------------------------------

# create department or return existing
PavelBegunkov's avatar
PavelBegunkov committed
DROP FUNCTION IF EXISTS CreateDepartment //
CREATE FUNCTION CreateDepartment (
        `pName` VARCHAR(200) CHARSET utf8,
PavelBegunkov's avatar
PavelBegunkov committed
        `pFacultyID` INT(11)
    ) RETURNS INT(11) # department id or -1 if failed
    NO SQL
BEGIN
    DECLARE EXIT HANDLER FOR SQLEXCEPTION RETURN -1;
PavelBegunkov's avatar
PavelBegunkov committed

    INSERT INTO departments
        (Name, FacultyID) VALUES (pName, pFacultyID)
        ON DUPLICATE KEY UPDATE
            departments.ID = LAST_INSERT_ID(departments.ID);
PavelBegunkov's avatar
PavelBegunkov committed

    RETURN LAST_INSERT_ID();
END //

# -------------------------------------------------------------------------------------------
# Label: specializations
# -------------------------------------------------------------------------------------------
PavelBegunkov's avatar
PavelBegunkov committed

# -------------------------------------------------------------------------------------------
# Label: grades
PavelBegunkov's avatar
PavelBegunkov committed
# -------------------------------------------------------------------------------------------

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 //
PavelBegunkov's avatar
PavelBegunkov committed

# -------------------------------------------------------------------------------------------
# Label: groups
PavelBegunkov's avatar
PavelBegunkov committed
# -------------------------------------------------------------------------------------------

# 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
PavelBegunkov's avatar
PavelBegunkov committed
    NO SQL
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)
        ON DUPLICATE KEY UPDATE
            study_groups.ID = LAST_INSERT_ID(study_groups.ID);
    RETURN LAST_INSERT_ID();
DROP FUNCTION IF EXISTS GetGroup//
CREATE FUNCTION `GetGroup` (
        `pGradeID` INT,
        `pGroupNum` INT,
        `pFacultyID` INT
    ) RETURNS int(11) # groupID or -1 if failed
    NO SQL
BEGIN
    DECLARE vGroupID INT DEFAULT -1;

    SELECT study_groups.ID INTO vGroupID
        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;

    RETURN vGroupID;
END //


DROP FUNCTION IF EXISTS GetStudentGroup//
CREATE FUNCTION `GetStudentGroup` (
    `pStudentID` INT,
    `pSemesterID` INT
) RETURNS int(11) # groupID or -1 if failed
    NO SQL
BEGIN
    DECLARE vGroupID INT DEFAULT -1;

    SELECT students_groups.GroupID INTO vGroupID
        FROM `students_groups`
        WHERE   students_groups.StudentID = pStudentID AND
                students_groups.SemesterID = pSemesterID
        LIMIT 1;

    RETURN vGroupID;
END //


PavelBegunkov's avatar
PavelBegunkov committed
# -------------------------------------------------------------------------------------------
# Label: subjects
# -------------------------------------------------------------------------------------------

DROP FUNCTION IF EXISTS CreateSubject//
CREATE FUNCTION `CreateSubject` (
        `pFacultyID` INT,
        `pSubjectName` TEXT CHARSET utf8,
PavelBegunkov's avatar
PavelBegunkov committed
        `pSubjectAbbr` VARCHAR(20) CHARSET utf8
    )   RETURNS int(11)
    NO SQL
BEGIN
    DECLARE vSubjectID INT DEFAULT -1;
    SET @vChecker := -1;
    # create/get subject (subject name is unique key)
    INSERT INTO `subjects`
        (Name, Abbr) VALUES (pSubjectName, pSubjectAbbr)
        ON DUPLICATE KEY UPDATE
            subjects.ID = ( @vChecker := LAST_INSERT_ID(subjects.ID));
    SET vSubjectID = LAST_INSERT_ID();
PavelBegunkov's avatar
PavelBegunkov committed

    BEGIN # handler block
        DECLARE EXIT HANDLER FOR SQLEXCEPTION RETURN -1;
PavelBegunkov's avatar
PavelBegunkov committed
        # try to attach subject to faculty
        INSERT INTO `subjects_faculties`
            (SubjectID, FacultyID) VALUES (vSubjectID, pFacultyID)
PavelBegunkov's avatar
PavelBegunkov committed
            ON DUPLICATE KEY UPDATE # just stub
                subjects_faculties.ID = LAST_INSERT_ID(subjects_faculties.ID);
PavelBegunkov's avatar
PavelBegunkov committed
    END;
    IF @vChecker > 0 THEN
        RETURN 1;
    ELSE
        RETURN 0;
    END IF;
PavelBegunkov's avatar
PavelBegunkov committed
DROP FUNCTION IF EXISTS DeleteSubject //
CREATE FUNCTION DeleteSubject (
        `pSubjectID` INT
    ) RETURNS INT(11) # 0 - success
PavelBegunkov's avatar
PavelBegunkov committed
    NO SQL
BEGIN
    DECLARE vChecker BOOLEAN DEFAULT FALSE;
PavelBegunkov's avatar
PavelBegunkov committed
    DECLARE EXIT HANDLER FOR SQLEXCEPTION RETURN -1;

    SET vChecker = EXISTS(
        SELECT * FROM `disciplines`
PavelBegunkov's avatar
PavelBegunkov committed
        WHERE disciplines.SubjectID = pSubjectID
        LIMIT 1
    );
    IF vChecker THEN
PavelBegunkov's avatar
PavelBegunkov committed
        RETURN -1; # Удаляемый предмет используется в disciplines.
    END IF;

    DELETE FROM `subjects_faculties`
        WHERE subjects_faculties.SubjectID = pSubjectID;
    DELETE FROM `subjects`
PavelBegunkov's avatar
PavelBegunkov committed
        WHERE subjects.ID = pSubjectID
        LIMIT 1;

    RETURN 0; # Успешно удалено;
END //

PavelBegunkov's avatar
PavelBegunkov committed

# -------------------------------------------------------------------------------------------
# Label: accounts
# -------------------------------------------------------------------------------------------




DROP FUNCTION IF EXISTS CheckAccountExistence//
CREATE FUNCTION `CheckAccountExistence` (
        `pData` TEXT CHARSET utf8,
        `pType` enum('login','email', 'code')
    ) RETURNS BOOLEAN # TRUE - exist, FALSE - doesn't
PavelBegunkov's avatar
PavelBegunkov committed
    NO SQL
BEGIN
    DECLARE vRes BOOLEAN DEFAULT FALSE;
    SET vRes = 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
    );
    RETURN vRes;
END //
# return:
#   -1 - unknown error.
#   -2 - code doesn't exists.
#   -3 - email already registered.
#   -4 - login already registered.
PavelBegunkov's avatar
PavelBegunkov committed
DROP FUNCTION IF EXISTS ActivateAccount//
CREATE FUNCTION `ActivateAccount` (
        `pCode` VARCHAR(40) CHARSET utf8,
PavelBegunkov's avatar
PavelBegunkov committed
        `pLogin` VARCHAR(50) CHARSET utf8,
        `pEMail` VARCHAR(50) CHARSET utf8,
        `pPassword` VARCHAR(255) CHARSET utf8
    ) RETURNS int(11)
PavelBegunkov's avatar
PavelBegunkov committed
    NO SQL
BEGIN
    DECLARE vExistEmail, vExistLogin BOOLEAN DEFAULT FALSE;
PavelBegunkov's avatar
PavelBegunkov committed
    # check for matching with existing accounts (note: Login & E-Mail are unique)
    DECLARE EXIT HANDLER FOR SQLEXCEPTION RETURN -1;

    SET vExistEmail = CheckAccountExistence(pEMail, 'email');
    IF vExistEmail THEN
        RETURN -3;
    END IF;
    SET vExistLogin = CheckAccountExistence(pLogin, 'login');
    IF vExistLogin THEN
        RETURN -4;
    END IF;

PavelBegunkov's avatar
PavelBegunkov committed
    # activate account
    UPDATE `accounts`
        SET accounts.Login = pLogin,
            accounts.Password = pPassword,
            accounts.EMail = pEMail,
            accounts.ActivationCode = NULL
        WHERE accounts.ActivationCode = pCode AND
              ( @vAccountID := accounts.ID ) # save accountID
PavelBegunkov's avatar
PavelBegunkov committed
        LIMIT 1;

    IF ( ROW_COUNT() = 0 ) THEN
PavelBegunkov's avatar
PavelBegunkov committed
        RETURN -2; # account with this Code not found
    ELSE
        RETURN @vAccountID;
PavelBegunkov's avatar
PavelBegunkov committed
    END IF;
END //


DROP FUNCTION IF EXISTS ChangeAccountData//
CREATE FUNCTION `ChangeAccountData` (
        `pUserID` INT,
        `pData` TEXT CHARSET utf8,
        `pType` enum('login', 'email', 'password')
    ) RETURNS int(11) # 0 - success, <0 - failed
PavelBegunkov's avatar
PavelBegunkov committed
    NO SQL
BEGIN
    DECLARE EXIT HANDLER FOR SQLEXCEPTION RETURN -1;

    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 = pData
                WHERE accounts.ID = pUserID
                LIMIT 1;
    END CASE;
    RETURN ROW_COUNT()-1;
PavelBegunkov's avatar
PavelBegunkov committed
END //



DROP FUNCTION IF EXISTS SignIn//
CREATE FUNCTION `SignIn` (
        `pLoginOrMail` VARCHAR(255) CHARSET utf8,
PavelBegunkov's avatar
PavelBegunkov committed
        `pPassword`  VARCHAR(64) CHARSET utf8
    ) RETURNS int(11) # account id
PavelBegunkov's avatar
PavelBegunkov committed
    NO SQL
BEGIN
    DECLARE vAccountID INT DEFAULT -1;

    #check account existence
    SELECT accounts.ID INTO vAccountID
PavelBegunkov's avatar
PavelBegunkov committed
        FROM `accounts`
        WHERE   accounts.Password = pPassword AND
                (accounts.Login = pLoginOrMail OR accounts.EMail = pLoginOrMail)
        LIMIT 1;
    IF vAccountID <= 0 THEN
        RETURN -1;
    END IF;

    # TODO: extract method - log sign in
    INSERT INTO `logs_signin` # logging
PavelBegunkov's avatar
PavelBegunkov committed
        (AccountID) VALUES (vAccountID);
    RETURN vAccountID;
END //




# -------------------------------------------------------------------------------------------
# Label: teachers
# -------------------------------------------------------------------------------------------

DROP FUNCTION IF EXISTS ChangeTeacherInfo//
CREATE FUNCTION `ChangeTeacherInfo` (
        `pTeacherID` INT,
PavelBegunkov's avatar
PavelBegunkov committed
        `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
PavelBegunkov's avatar
PavelBegunkov committed
    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;
PavelBegunkov's avatar
PavelBegunkov committed
END //



DROP FUNCTION IF EXISTS CreateTeacher//
CREATE FUNCTION `CreateTeacher` (
        `pLastName` VARCHAR(30) CHARSET utf8,
PavelBegunkov's avatar
PavelBegunkov committed
        `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
PavelBegunkov's avatar
PavelBegunkov committed
    NO SQL
BEGIN
    DECLARE vAccountID INT DEFAULT -1;
    DECLARE EXIT HANDLER FOR SQLEXCEPTION RETURN -1;

    # TODO: kill magic constants
    # user role 2 - common teacher
    # create account
PavelBegunkov's avatar
PavelBegunkov committed
    INSERT INTO `accounts`
        (Login , Password , EMail, UserRoleID, ActivationCode )
        VALUES  ( NULL, NULL, NULL, 2, pActivationCode);
    SET vAccountID = LAST_INSERT_ID();

    # add new teacher
PavelBegunkov's avatar
PavelBegunkov committed
    INSERT INTO `teachers`
        (AccountID, LastName, FirstName, SecondName, JobPositionID, DepartmentID)
        VALUES  (vAccountID, pLastName, pFirstName, pSecondName, pJobPositionID, pDepartmentID);
    RETURN ROW_COUNT()-1;
END //


DROP FUNCTION IF EXISTS CreateTeacherByDepName//
CREATE FUNCTION `CreateTeacherByDepName` (
        `pLastName` VARCHAR(30) CHARSET utf8,
PavelBegunkov's avatar
PavelBegunkov committed
        `pFirstName` VARCHAR(30) CHARSET utf8,
        `pSecondName` VARCHAR(30) CHARSET utf8,
        `pDepartmentName` VARCHAR(200) CHARSET utf8,
PavelBegunkov's avatar
PavelBegunkov committed
        `pActivationCode` VARCHAR(40) CHARSET utf8
    )   RETURNS int(11) # 0 - success, < 0 - failed
PavelBegunkov's avatar
PavelBegunkov committed
    NO SQL
BEGIN
    DECLARE vAccountID, vRoleID, vDepID INT DEFAULT -1;
PavelBegunkov's avatar
PavelBegunkov committed
    DECLARE EXIT HANDLER FOR SQLEXCEPTION RETURN -1;

    SET vDepID = CreateDepartment(pDepartmentName, pFacultyID);
    IF vDepID < 0 THEN
       RETURN -1;
    RETURN CreateTeacher(pLastName, pFirstName, pSecondName, 12, vDepID, pActivationCode);
PavelBegunkov's avatar
PavelBegunkov committed
-- -1 - не сотрудник деканата и не преподаватель дисциплины
-- 0 - только чтение
-- 1 - редактирование
DROP FUNCTION IF EXISTS GetEditRightsForTeacher//
CREATE FUNCTION `GetEditRightsForTeacher` (
        `pTeacherID` INT,
PavelBegunkov's avatar
PavelBegunkov committed
        `pDisciplineID` INT
    ) RETURNS int(11)
PavelBegunkov's avatar
PavelBegunkov committed
    NO SQL
BEGIN
    DECLARE vUserRole INT DEFAULT -1;
    DECLARE vIsBound BOOLEAN;
    SET vIsBound = InternalIsTeacherBound(pTeacherID, pDisciplineID);
    IF vIsBound > 0 THEN
PavelBegunkov's avatar
PavelBegunkov committed
        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;
    # TODO: magic constants
PavelBegunkov's avatar
PavelBegunkov committed
    IF vUserRole = 4 THEN # 4 - сотрудник деканата
        RETURN 0;
    END IF;

    RETURN -1;
END //


PavelBegunkov's avatar
PavelBegunkov committed

# -------------------------------------------------------------------------------------------
# Label: students
# -------------------------------------------------------------------------------------------

# TODO: magic constants (UserRoleID)
# TODO: group id instead num and grade
PavelBegunkov's avatar
PavelBegunkov committed
DROP FUNCTION IF EXISTS CreateStudent//
CREATE FUNCTION `CreateStudent` (
        `pLastName` VARCHAR(30) CHARSET utf8,
PavelBegunkov's avatar
PavelBegunkov committed
        `pFirstName` VARCHAR(30) CHARSET utf8,
        `pSecondName` VARCHAR(30) CHARSET utf8,
        `pGradeID` INT,
        `pGroupNum` INT,
        `pFacultyID` INT,
        `pActivationCode` VARCHAR(40) CHARSET utf8,
        `pSemesterID` INT
PavelBegunkov's avatar
PavelBegunkov committed
    )   RETURNS int(11)
    NO SQL
BEGIN
    DECLARE vAccountID, vGroupID, vStudentID, vSemesterID INT DEFAULT -1;
PavelBegunkov's avatar
PavelBegunkov committed
    DECLARE EXIT HANDLER FOR SQLEXCEPTION RETURN -1;

    SET vGroupID = GetGroup(pGradeID, pGroupNum, pFacultyID);
PavelBegunkov's avatar
PavelBegunkov committed
    IF vGroupID <= 0 THEN
        RETURN -1;
    END IF;

    # create new account
    # UserRoleID 1 = student
PavelBegunkov's avatar
PavelBegunkov committed
    INSERT INTO `accounts`
        (Login , Password , EMail, UserRoleID, ActivationCode )
        VALUES ( NULL, NULL, NULL, 1, pActivationCode);
    SET vAccountID = LAST_INSERT_ID();

    # create student
    INSERT INTO `students`
        (AccountID, LastName, FirstName, SecondName)
        VALUES  (vAccountID, pLastName, pFirstName, pSecondName);
    SET vStudentID = LAST_INSERT_ID();
    RETURN ControlStudentGroup(vStudentID, vGroupID, FALSE, pSemesterID);
# unlike fn CreateStudent, this can create all missing records (group, grade, specialization)
PavelBegunkov's avatar
PavelBegunkov committed
DROP FUNCTION IF EXISTS CreateStudentEx//
CREATE FUNCTION `CreateStudentEx` (
        `pLastName` VARCHAR(30) CHARSET utf8,
PavelBegunkov's avatar
PavelBegunkov committed
        `pFirstName` VARCHAR(30) CHARSET utf8,
        `pSecondName` VARCHAR(30) CHARSET utf8,
        `pGradeNum` INT,
        `pGroupNum` INT,
        `pDegree` enum('bachelor', 'master', 'specialist'),
PavelBegunkov's avatar
PavelBegunkov committed
        `pSpecName` VARCHAR(50) CHARSET utf8,
        `pFacultyID` INT,
        `pActivationCode` VARCHAR(40) CHARSET utf8,
        `pSemesterID` INT
PavelBegunkov's avatar
PavelBegunkov committed
    )   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, vGradeID, pGroupNum, pFacultyID, pActivationCode, pSemesterID);
xamgore's avatar
xamgore committed
# Give a student an academic leave or attach him to group.
#   params:
#      StudentID (int)
#      GroupID (int)   : is used, if OnLeave == false
#      OnLeave (bool)  : true - into study leave, false - attach to group
DROP FUNCTION IF EXISTS ControlStudentGroup//
xamgore's avatar
xamgore committed
CREATE FUNCTION `ControlStudentGroup` (
        `pStudentID` INT,
xamgore's avatar
xamgore committed
        `pGroupID` INT,
        `pState` BOOLEAN,
        `pSemesterID` INT
    ) RETURNS int(11)
    NO SQL
BEGIN
    DECLARE vChecker INT DEFAULT 0;
    DECLARE EXIT HANDLER FOR SQLEXCEPTION RETURN -1;

xamgore's avatar
xamgore committed
    # out to study leave
    IF pState THEN
        UPDATE `students_groups`
            SET students_groups.IsStudyLeave = TRUE,
                students_groups.Date = CURDATE()
            WHERE students_groups.StudentID = pStudentID AND
                  students_groups.SemesterID = pSemesterID
xamgore's avatar
xamgore committed
    # attach to new group
    ELSE
        INSERT INTO `students_groups`
            (StudentID, GroupID, SemesterID)
            VALUES(pStudentID, pGroupID, pSemesterID)
            ON DUPLICATE KEY UPDATE
                students_groups.GroupID = pGroupID;
    END IF;
    RETURN ROW_COUNT()-1;
END //

PavelBegunkov's avatar
PavelBegunkov committed

# -------------------------------------------------------------------------------------------
# Label: disciplines
# -------------------------------------------------------------------------------------------


DROP FUNCTION IF EXISTS Discipline_Create//
CREATE FUNCTION `Discipline_Create` (
    `pTeacherID` INT,
    `pGradeID` INT,
    `pSubjectID` INT,
PavelBegunkov's avatar
PavelBegunkov committed
    `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)
PavelBegunkov's avatar
PavelBegunkov committed
    NO SQL
BEGIN
    DECLARE vChecker, 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
PavelBegunkov's avatar
PavelBegunkov committed
    INSERT INTO `disciplines`
        (AuthorID, GradeID, SubjectID, ExamType,
        LectureCount, PracticeCount,LabCount,
        SemesterID, FacultyID, Subtype)
            pTeacherID, pGradeID, pSubjectID, pExamType,
            pLectureCount, pPracticeCount, pLabCount,
            pSemesterID, pFacultyID, pSubtype
PavelBegunkov's avatar
PavelBegunkov committed
    SET vDisciplineID = LAST_INSERT_ID();

    SET vChecker = Discipline_BindTeacher(vDisciplineID, pTeacherID);
    # add exam and extra modules
PavelBegunkov's avatar
PavelBegunkov committed
    IF pExamType = 'exam' THEN
        SET vChecker = AddModuleExam(pTeacherID, vDisciplineID);
    END IF;
    SET vChecker = AddModuleExtra(pTeacherID, vDisciplineID);
PavelBegunkov's avatar
PavelBegunkov committed
    RETURN vDisciplineID;
END //



DROP FUNCTION IF EXISTS ChangeDisciplineSubject//
CREATE FUNCTION `ChangeDisciplineSubject` (
        `pTeacherID` INT,
        `pDisciplineID` INT,
        `pSubjectID` INT
PavelBegunkov's avatar
PavelBegunkov committed
    ) RETURNS int(11)
    NO SQL
BEGIN
    DECLARE EXIT HANDLER FOR SQLEXCEPTION RETURN -1;

    IF  NOT InternalIsTeacherAuthor(pTeacherID, pDisciplineID) OR
PavelBegunkov's avatar
PavelBegunkov committed
        InternalIsMapLocked(pDisciplineID)
    THEN
        RETURN -1;
    END IF;

    UPDATE `disciplines`
        SET disciplines.SubjectID = pSubjectID
        WHERE disciplines.ID = pDisciplineID
        LIMIT 1;
    RETURN ROW_COUNT()-1;
END //



PavelBegunkov's avatar
PavelBegunkov committed
DROP FUNCTION IF EXISTS GetMilestone//
CREATE FUNCTION `GetMilestone` (
        `pFacultyID` INT,
        `pSemesterID` INT
PavelBegunkov's avatar
PavelBegunkov committed
    ) RETURNS int(11)
    NO SQL
BEGIN
    DECLARE vMilestone, vCounter INT DEFAULT 0;

    # get most frequent milestone
PavelBegunkov's avatar
PavelBegunkov committed
    SELECT COUNT(*) AS 'cnt', disciplines.Milestone
        INTO vCounter, vMilestone
PavelBegunkov's avatar
PavelBegunkov committed
        FROM `disciplines`
        WHERE disciplines.SemesterID = pSemesterID AND
              disciplines.FacultyID = pFacultyID
        GROUP BY disciplines.Milestone
        ORDER BY cnt DESC
        LIMIT 1;

    RETURN vMilestone;
END //



PavelBegunkov's avatar
PavelBegunkov committed
DROP FUNCTION IF EXISTS ChangeDisciplineGrade//
CREATE FUNCTION `ChangeDisciplineGrade` (
        `pTeacherID` INT,
        `pDisciplineID` INT,
        `pGradeID` INT
PavelBegunkov's avatar
PavelBegunkov committed
    ) RETURNS int(11)
    NO SQL
BEGIN
PavelBegunkov's avatar
PavelBegunkov committed
    DECLARE vCurGradeID INT DEFAULT -1;
PavelBegunkov's avatar
PavelBegunkov committed
    DECLARE EXIT HANDLER FOR SQLEXCEPTION RETURN -1;

    IF  InternalIsMapLocked(pDisciplineID) OR
        NOT InternalIsTeacherAuthor(pTeacherID, pDisciplineID)
    THEN
        RETURN -1;
    END IF;

PavelBegunkov's avatar
PavelBegunkov committed
    SET vCurGradeID = GetDisciplineProperty(pDisciplineID, 'grade');
PavelBegunkov's avatar
PavelBegunkov committed
    IF vCurGradeID = pGradeID THEN
        RETURN 0;
PavelBegunkov's avatar
PavelBegunkov committed
    END IF;

PavelBegunkov's avatar
PavelBegunkov committed
    # delete all students
    DELETE FROM `disciplines_groups`
        WHERE disciplines_groups.DisciplineID = pDisciplineID;
    DELETE FROM `disciplines_students`
        WHERE disciplines_students.DisciplineID = pDisciplineID;

    # set grade
PavelBegunkov's avatar
PavelBegunkov committed
    UPDATE `disciplines`
        SET disciplines.GradeID = pGradeID
        WHERE disciplines.ID = pDisciplineID
        LIMIT 1;
    RETURN ROW_COUNT()-1;
END //


DROP FUNCTION IF EXISTS ChangeDisciplineControl//
CREATE FUNCTION `ChangeDisciplineControl` (
        `pTeacherID` INT,
        `pDisciplineID` INT,
        `pExamType` enum('exam', 'credit', 'grading_credit')
PavelBegunkov's avatar
PavelBegunkov committed
    )   RETURNS int(11)
    NO SQL
BEGIN
    DECLARE vChecker, vExtraMax, vExtraID INT DEFAULT -1;
PavelBegunkov's avatar
PavelBegunkov committed
    DECLARE vOldExamType enum('exam', 'credit', 'grading_credit');
PavelBegunkov's avatar
PavelBegunkov committed
    DECLARE EXIT HANDLER FOR SQLEXCEPTION RETURN -1;

    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'
PavelBegunkov's avatar
PavelBegunkov committed
        LIMIT 1;
    IF vExtraID <= 0 THEN
        RETURN -1;
    END IF;
PavelBegunkov's avatar
PavelBegunkov committed
    # check type changing: exam <-> credit/grading_credit
    IF NOT (vOldExamType = 'exam' XOR pExamType != 'exam') THEN

        # TODO: extract method addExtraModule