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//

# -------------------------------------------------------------------------------------------
# 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
    NO SQL
BEGIN
PavelBegunkov's avatar
PavelBegunkov committed
    RETURN EXISTS(
        SELECT * FROM `disciplines`
        WHERE disciplines.ID = pDisciplineID AND disciplines.isLocked = 1
    );
PavelBegunkov's avatar
PavelBegunkov committed
33 34 35 36 37 38 39 40 41 42 43 44 45 46 47 48 49 50 51 52 53 54 55 56 57 58 59 60 61 62 63 64 65 66 67 68 69 70 71 72 73 74 75 76 77 78 79 80 81 82 83 84 85 86 87 88 89 90 91 92 93 94 95 96 97 98 99 100 101 102 103 104 105 106 107 108 109 110 111 112 113 114 115 116 117 118 119 120 121 122 123 124 125 126 127 128 129 130 131 132 133 134 135 136 137 138 139 140 141 142 143 144 145 146 147 148 149 150 151 152 153 154 155 156 157 158 159 160 161 162 163 164 165 166 167 168 169 170 171 172 173 174 175 176 177 178 179 180 181 182 183 184 185 186 187 188 189 190 191 192 193 194 195 196 197 198 199 200 201 202 203 204 205 206 207 208 209 210 211 212 213 214 215 216 217 218 219 220 221 222 223 224 225 226 227 228 229 230 231 232 233 234 235 236 237 238 239 240 241 242 243 244 245 246 247 248 249 250 251 252 253 254 255 256 257 258 259 260 261 262 263 264 265 266 267 268 269 270 271 272 273 274 275 276 277 278 279 280 281 282 283 284 285 286 287 288 289 290 291 292 293 294 295 296 297 298 299 300 301 302 303 304 305 306 307 308 309 310 311 312 313 314 315 316 317 318 319 320 321 322 323 324 325 326 327 328 329 330 331 332 333 334 335 336 337 338 339 340 341 342 343 344 345 346 347 348 349 350 351 352 353 354 355 356 357 358 359 360 361 362 363 364 365 366 367 368 369 370 371 372 373 374 375 376 377 378 379 380 381 382 383 384 385 386 387 388 389 390 391 392 393 394 395 396 397 398 399 400 401 402 403 404 405 406 407 408 409 410 411 412 413 414 415 416 417 418 419 420 421 422 423 424 425 426 427 428 429 430 431 432 433 434 435 436 437 438 439 440 441 442 443 444 445
END //


# check, that student really take this course
DROP FUNCTION IF EXISTS InternalIsStudentAttached//
CREATE FUNCTION `InternalIsStudentAttached`
    (`pStudentID` INT, `pDisciplineID` INT) RETURNS BOOLEAN
    NO SQL
BEGIN
    RETURN EXISTS(
        SELECT * FROM `view_disciplines_students`
        WHERE view_disciplines_students.StudentID = pStudentID AND
              view_disciplines_students.DisciplineID = pDisciplineID AND
              (view_disciplines_students.AttachType IS NULL OR
                  view_disciplines_students.AttachType = 'attach')
        );
END //


# check, that teacher teach this course
drop function if exists InternalIsTeacherBounded//
CREATE FUNCTION `InternalIsTeacherBounded`
    (   `pTeacherID` INT, `pDisciplineID` INT) RETURNS BOOLEAN
    NO SQL
BEGIN
    RETURN EXISTS (SELECT * FROM `disciplines_teachers`
                   WHERE disciplines_teachers.TeacherID = pTeacherID AND
                         disciplines_teachers.DisciplineID = pDisciplineID);
END //


DROP FUNCTION IF EXISTS InternalIsTeacherAuthor//
CREATE FUNCTION `InternalIsTeacherAuthor`
    (   `pTeacherID` INT, `pDisciplineID` INT) RETURNS BOOLEAN
    NO SQL
BEGIN
    RETURN EXISTS (SELECT * FROM `disciplines`
                    WHERE disciplines.ID = pDisciplineID AND disciplines.AuthorID = pTeacherID);
END //


DROP FUNCTION IF EXISTS GetDisciplineMaxRate//
CREATE FUNCTION `GetDisciplineMaxRate`
    (   `pDisciplineID` INT) RETURNS int(11)
    NO SQL
BEGIN
    DECLARE vMaxRate INT DEFAULT 0;

    # discipline map consist of submodules, we sum all their max rates
    SELECT SUM(submodules.MaxRate)
        INTO vMaxRate
        FROM `submodules`
        INNER JOIN `modules`
            ON  submodules.ModuleID = modules.ID AND (modules.Type = 'regular' OR modules.Type = 'exam')
        WHERE modules.DisciplineID = pDisciplineID;

    RETURN vMaxRate;
END //


DROP FUNCTION IF EXISTS GetRateForDisc//
CREATE FUNCTION `GetRateForDisc`
    (   `pStudentID` INT, `pDisciplineID` INT) RETURNS int(11)
    NO SQL
BEGIN
    DECLARE vRate INT DEFAULT -1;

    SELECT SUM(rating_table.Rate)
        INTO vRate
        FROM `rating_table`
        INNER JOIN `submodules` ON  rating_table.SubmoduleID = submodules.ID
        INNER JOIN `modules`    ON  submodules.ModuleID = modules.ID AND
                                    modules.DisciplineID = pDisciplineID
        WHERE   rating_table.StudentID = pStudentID AND
            (   modules.Type != 'exam' OR
                submodules.ID =
                    (   SELECT submodules.ID
                        FROM `submodules`
                        INNER JOIN `rating_table` ON rating_table.SubModuleID = submodules.ID
                        WHERE   submodules.ModuleID = modules.ID AND
                                rating_table.StudentID = pStudentID
                        ORDER BY submodules.OrderNum DESC
                        LIMIT 1
                    )
            )
        LIMIT 1;

    RETURN  vRate;
END //


DROP FUNCTION IF EXISTS GetRateForDiscSemester//
CREATE FUNCTION `GetRateForDiscSemester`
    (   `pStudentID` INT, `pDisciplineID` INT) RETURNS int(11)
    NO SQL
BEGIN
    DECLARE vRate INT DEFAULT -1;

    SELECT SUM(rating_table.Rate)
        INTO vRate
        FROM `rating_table`
        INNER JOIN `submodules` ON  rating_table.SubmoduleID = submodules.ID
        INNER JOIN `modules`    ON  submodules.ModuleID = modules.ID
        WHERE   rating_table.StudentID = pStudentID AND
                modules.DisciplineID = pDisciplineID AND
                modules.Type = 'regular'
        LIMIT 1;

    RETURN vRate;
END //


DROP FUNCTION IF EXISTS GetRateForDiscBonus//
CREATE FUNCTION `GetRateForDiscBonus`
    (   `pStudentID` INT, `pDisciplineID` INT) RETURNS int(11)
    NO SQL
BEGIN
    DECLARE vRate INT DEFAULT -1;

    SELECT SUM(rating_table.Rate)
        INTO vRate
        FROM `rating_table`
        INNER JOIN `submodules` ON  rating_table.SubmoduleID = submodules.ID
        INNER JOIN `modules`    ON  submodules.ModuleID = modules.ID
        WHERE   rating_table.StudentID = pStudentID AND
                modules.DisciplineID = pDisciplineID AND
                modules.Type = 'bonus'
        LIMIT 1;

    RETURN  vRate;
END //




DROP FUNCTION IF EXISTS GetRateForDiscExam//
CREATE FUNCTION `GetRateForDiscExam`
    (   `pStudentID` INT, `pDisciplineID` INT) RETURNS int(11)
    NO SQL
BEGIN
    DECLARE vRate INT DEFAULT -1;

    SELECT rating_table.Rate
        INTO vRate
        FROM `rating_table`
        INNER JOIN `submodules` ON  rating_table.SubmoduleID = submodules.ID
        INNER JOIN `modules`    ON  submodules.ModuleID = modules.ID
        WHERE   rating_table.StudentID = pStudentID AND
                modules.DisciplineID = pDisciplineID AND
                modules.Type = 'exam'
        ORDER BY submodules.OrderNum DESC
        LIMIT 1;

    RETURN  vRate;
END //


DROP FUNCTION IF EXISTS GetRateForDiscExamNum//
CREATE FUNCTION `GetRateForDiscExamNum`
    (   `pStudentID` INT, `pDisciplineID` INT, `pOrderNum` INT
    ) RETURNS int(11)
    NO SQL
BEGIN
    DECLARE vRate INT DEFAULT -1;

    SELECT rating_table.Rate
        INTO vRate
        FROM `rating_table`
        INNER JOIN `submodules` ON  rating_table.SubmoduleID = submodules.ID
        INNER JOIN `modules`    ON  submodules.ModuleID = modules.ID
        WHERE   rating_table.StudentID = pStudentID AND
                modules.DisciplineID = pDisciplineID AND
                modules.Type = 'exam' AND
                submodules.OrderNum = pOrderNum
        LIMIT 1;

    RETURN  vRate;
END //


DROP FUNCTION IF EXISTS GetRateForDiscExtra//
CREATE FUNCTION `GetRateForDiscExtra`
    (   `pStudentID` INT, `pDisciplineID` INT, `pOrderNum` INT
    ) RETURNS int(11)
    NO SQL
BEGIN
    DECLARE vRate INT DEFAULT -1;

    SELECT rating_table.Rate
        INTO vRate
        FROM `rating_table`
        INNER JOIN `submodules` ON  rating_table.SubmoduleID = submodules.ID
        INNER JOIN `modules`    ON  submodules.ModuleID = modules.ID
        WHERE   rating_table.StudentID = pStudentID AND
                modules.DisciplineID = pDisciplineID AND
                modules.Type = 'extra' AND
                submodules.OrderNum = pOrderNum
        LIMIT 1;

    RETURN  vRate;
END //


# check, if any module is created
DROP FUNCTION IF EXISTS InternalIsMapCreated//
CREATE FUNCTION `InternalIsMapCreated`
    (   `pDisciplineID` INT) RETURNS int(11)
    NO SQL
BEGIN
    RETURN EXISTS (
        SELECT * FROM `view_disciplines_results`
        WHERE view_disciplines_results.DisciplineID = pDisciplineID AND
              view_disciplines_results.DisciplineRateMax = 100
    );
END //



# set notification flag
DROP FUNCTION IF EXISTS InternalNotify//
CREATE FUNCTION `InternalNotify`        (   `AccountID` INT
                                        )   RETURNS int(11)
    NO SQL
BEGIN
    UPDATE `accounts`
        SET accounts.Notification = 1
        WHERE accounts.ID = AccountID
        LIMIT 1;
    RETURN ROW_COUNT()-1;
END //




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

DROP FUNCTION IF EXISTS SetSettings//
CREATE FUNCTION `SetSettings`
    (`pKey` VARCHAR(50) CHARSET utf8, `pVal` INT, `pValS` VARCHAR(300) CHARSET utf8
    ) RETURNS int(11)
    NO SQL
BEGIN
    INSERT INTO `general_settings`
        (Val, ValS, Name) VALUES(pVal, pValS, pKey)
        ON DUPLICATE KEY UPDATE
            general_settings.Val = pVal,
            general_settings.ValS = pValS;
        RETURN 0;
END//



DROP FUNCTION IF EXISTS SetBitmaskByPagename//
CREATE FUNCTION `SetBitmaskByPagename`
    (`pPagename` TEXT CHARSET utf8, `pMask` INT) RETURNS int(11)
    NO SQL
BEGIN
    INSERT INTO `page_access`
        (Pagename, Bitmask) VALUES(pPagename, pMask)
        ON DUPLICATE KEY UPDATE
            page_access.Bitmask = pMask;
    RETURN 0;
END //



DROP FUNCTION IF EXISTS GetBitmaskByPagename//
CREATE FUNCTION `GetBitmaskByPagename` (`pPagename` TEXT CHARSET utf8) RETURNS int(11)
    NO SQL
BEGIN
    RETURN (SELECT page_access.Bitmask
                FROM `page_access`
                WHERE page_access.Pagename = pPagename
                LIMIT 1);
END //




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

DROP FUNCTION IF EXISTS SetSemesterID//
CREATE FUNCTION `SetSemesterID` (`pSemesterID` INT) RETURNS int(11)
    NO SQL
BEGIN
    SET @CurrentSemesterID = pSemesterID;
    RETURN 0;
END //




# -------------------------------------------------------------------------------------------
# Label: study groups
# -------------------------------------------------------------------------------------------

DROP FUNCTION IF EXISTS CreateStudyGroup//
CREATE FUNCTION `CreateStudyGroup`
    (   `pGradeID` INT, `pGroupNum` INT,
        `pSpecializationID` INT, `pGroupName` VARCHAR(50) CHARSET utf8
    )   RETURNS int(11)
    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);
    RETURN 0;
END //


# -------------------------------------------------------------------------------------------
# Label: subjects
# -------------------------------------------------------------------------------------------

DROP FUNCTION IF EXISTS CreateSubject//
CREATE FUNCTION `CreateSubject`
    (   `pFacultyID` INT,
        `pSubjectName` VARCHAR(200) CHARSET utf8,
        `pSubjectAbbr` VARCHAR(20) CHARSET utf8
    )   RETURNS int(11)
    NO SQL
BEGIN
    DECLARE vSubjectID INT DEFAULT -1;

    # find same subject
    SELECT subjects.ID INTO vSubjectID
        FROM `subjects`
        WHERE subjects.Name = pSubjectName
        LIMIT 1;
    IF vSubjectID <= 0 THEN
        # create new subject
        INSERT INTO `subjects`
            (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 //



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

# TODO: rename
DROP FUNCTION IF EXISTS GetAccCountByCode//
CREATE FUNCTION `GetAccCountByCode` (`pCode` VARCHAR(40) CHARSET utf8) RETURNS int(11)
    NO SQL
BEGIN
    RETURN EXISTS(SELECT * FROM `accounts` WHERE accounts.ActivationCode = pCode);
END //


DROP FUNCTION IF EXISTS GetAccCountByMail //
CREATE FUNCTION `GetAccCountByMail` (`pEMail` VARCHAR(50) CHARSET utf8) RETURNS int(11)
    NO SQL
BEGIN
    RETURN EXISTS(SELECT * FROM `accounts` WHERE accounts.EMail = pEMail);
END //


DROP FUNCTION IF EXISTS GetAccCountByLogin//
CREATE FUNCTION `GetAccCountByLogin` (`pLogin` VARCHAR(50) CHARSET utf8) RETURNS int(11)
    NO SQL
BEGIN
    RETURN EXISTS(SELECT * FROM `accounts` WHERE accounts.Login = pLogin);
END //




DROP FUNCTION IF EXISTS ActivateAccount//
CREATE FUNCTION `ActivateAccount`
    (   `pCode` VARCHAR(40) CHARSET utf8,
        `pLogin` VARCHAR(50) CHARSET utf8,
        `pEMail` VARCHAR(50) CHARSET utf8,
        `pPassword` VARCHAR(255) CHARSET utf8
    )   RETURNS int(11)
    NO SQL
BEGIN
    # check for matching with existing accounts (note: Login & E-Mail are unique)
    DECLARE EXIT HANDLER FOR SQLEXCEPTION RETURN -1;

    # 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) > 0 # save accountID
        LIMIT 1;

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



DROP FUNCTION IF EXISTS ChangePassword//
CREATE FUNCTION `ChangePassword`
    (   `pUserID` INT, `pPassword` VARCHAR(255) CHARSET utf8
    )   RETURNS int(11)
    NO SQL
BEGIN
    DECLARE EXIT HANDLER FOR SQLEXCEPTION RETURN -1;

    # set new password
    UPDATE `accounts`
        SET accounts.Password = pPassword
        WHERE accounts.ID = pUserID
        LIMIT 1;
    RETURN ROW_COUNT()-1; # -1 if account doesn't exists, otherwise 0
END //



DROP FUNCTION IF EXISTS ChangeLogin//
CREATE FUNCTION `ChangeLogin`
    (   `pUserID` INT, `pLogin` VARCHAR(50) CHARSET utf8
    )   RETURNS int(11)
    NO SQL
BEGIN
    # 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 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
    )   RETURNS int(11)
    NO SQL
BEGIN
    # 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 ROW_COUNT()-1; # -1 if account doesn't exists, otherwise 0
END //



DROP FUNCTION IF EXISTS SignIn//
CREATE FUNCTION `SignIn`
    (   `pLoginOrMail` VARCHAR(255) CHARSET utf8,
        `pPassword`  VARCHAR(64) CHARSET utf8
    )   RETURNS int(11)
    NO SQL
BEGIN
    DECLARE vAccountID INT DEFAULT -1;

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

    # logging
    INSERT INTO `logs_signin`
        (AccountID) VALUES (vAccountID);
    RETURN vAccountID;
END //




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

DROP FUNCTION IF EXISTS ChangeTeacherInfo//
CREATE FUNCTION `ChangeTeacherInfo`
    (   `pTeacherID` INT,
        `pLastName` VARCHAR(30) CHARSET utf8,
        `pFirstName` VARCHAR(30) CHARSET utf8,
        `pSecondName` VARCHAR(30) CHARSET utf8,
        `pJobPositionID` INT,
        `pDepartmentID` INT
    ) RETURNS int(11)
    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; # -1 if teacher doesn't exists, otherwise 0
END //



DROP FUNCTION IF EXISTS CreateTeacher//
CREATE FUNCTION `CreateTeacher`
    (   `pLastName` VARCHAR(30) CHARSET utf8,
        `pFirstName` VARCHAR(30) CHARSET utf8,
        `pSecondName` VARCHAR(30) CHARSET utf8,
        `pJobPositionID` INT,
        `pDepartmentID`  INT,
        `pActivationCode` VARCHAR(40) CHARSET utf8
    ) RETURNS int(11)
    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 )
        VALUES  ( NULL, NULL, NULL, 2, pActivationCode);
    SET vAccountID = LAST_INSERT_ID();

# add new teacher
    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,
        `pFirstName` VARCHAR(30) CHARSET utf8,
        `pSecondName` VARCHAR(30) CHARSET utf8,
        `pDepartmentName` VARCHAR(200) CHARSET utf8,
        `pActivationCode` VARCHAR(40) CHARSET utf8
    )   RETURNS int(11)
    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
        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;

    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 //



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

DROP FUNCTION IF EXISTS CreateStudent//
CREATE FUNCTION `CreateStudent`
    (   `pLastName` VARCHAR(30) CHARSET utf8,
        `pFirstName` VARCHAR(30) CHARSET utf8,
        `pSecondName` VARCHAR(30) CHARSET utf8,
        `pGradeID` INT, `pGroupNum` INT, `pFacultyID` INT,
        # TODO: delete pGradeID
        `pActivationCode` VARCHAR(40) CHARSET utf8
    )   RETURNS int(11)
    NO SQL
BEGIN
    DECLARE vAccountID, vGroupID INT DEFAULT -1;
    DECLARE EXIT HANDLER FOR SQLEXCEPTION RETURN -1;

    # find group
    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;

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

    # create student
    INSERT INTO `students`
        (GroupID, AccountID, LastName, FirstName, SecondName)
        VALUES  (vGroupID, vAccountID, pLastName, pFirstName, pSecondName);
    RETURN 0;
END //


PavelBegunkov's avatar
PavelBegunkov committed

PavelBegunkov's avatar
PavelBegunkov committed
DROP FUNCTION IF EXISTS CreateStudentEx//
CREATE FUNCTION `CreateStudentEx`
    (   `pLastName` VARCHAR(30) CHARSET utf8,
        `pFirstName` VARCHAR(30) CHARSET utf8,
        `pSecondName` VARCHAR(30) CHARSET utf8,
        `pGradeNum` INT, `pGroupNum` INT,
        `pDegree` VARCHAR(20) CHARSET utf8,
        `pSpecName` VARCHAR(50) CHARSET utf8,
        `pFacultyID` INT,
        `pActivationCode` VARCHAR(40) CHARSET utf8
    )   RETURNS int(11)
    NO SQL
BEGIN
    DECLARE vAccountID, vGradeID, vSpecID, vGroupID INT DEFAULT -1;
    DECLARE EXIT HANDLER FOR SQLEXCEPTION RETURN -1;

    # try to find grade
    SELECT grades.ID INTO vGradeID
        FROM `grades`
        WHERE grades.Num = pGradeNum AND grades.Degree = pDegree
        LIMIT 1;
    # such grade doesn't exist
    IF vGradeID <= 0 THEN
        # insert new grade with pGradeNum and pDegree
        INSERT INTO `grades`
            (Num, Degree) VALUES (pGradeNum, pDegree);
        SET vGradeID = LAST_INSERT_ID();
    END IF;

    # try to find group
    SELECT view_groups.GroupID INTO vGroupID
        FROM `view_groups`
        WHERE view_groups.FacultyID = pFacultyID AND
            view_groups.GroupNum = pGroupNum AND
            view_groups.GradeID = vGradeID
        LIMIT 1;

    # group not found
    IF vGroupID <= 0 THEN
        # try to find specialization
        SELECT specializations.ID INTO vSpecID
            FROM `specializations`
            WHERE   (specializations.Name = pSpecName OR
                        (pSpecName = '' AND specializations.Name IS NULL)) AND
                    specializations.FacultyID = pFacultyID
            LIMIT 1;

        # specialization not found
        IF vSpecID <= 0 THEN
            # create new specialization
            INSERT INTO `specializations`
                (Name, Abbr, FacultyID)
                VALUES  (pSpecName, NULL, pFacultyID);
            SET vSpecID = LAST_INSERT_ID();
        END IF;

        # create new group
        INSERT INTO `study_groups`
            (GradeID, GroupNum, SpecializationID)
            VALUES (vGradeID, pGroupNum, vSpecID);
        SET vGroupID = LAST_INSERT_ID();
    END IF;

    # TODO: user roles
    # create account
    INSERT INTO `accounts`
        (Login, Password , EMail, UserRoleID, ActivationCode )
        VALUES  ( NULL, NULL, NULL, 1, pActivationCode);
    SET vAccountID = LAST_INSERT_ID();

    # create student
    INSERT INTO `students`
        (GroupID, AccountID, LastName, FirstName, SecondName)
        VALUES (vGroupID, vAccountID, pLastName, pFirstName, pSecondName);
    RETURN ROW_COUNT()-1;
END //




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

DROP FUNCTION IF EXISTS OrderModuleTypesForSession//
CREATE FUNCTION `OrderModuleTypesForSession`
    (`pModuleType` INT ) RETURNS INT(3)
	NO SQL
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 vRes;
END //



DROP FUNCTION IF EXISTS AddDiscipline//
CREATE FUNCTION `AddDiscipline`
    (   `pTeacherID` INT, `pGradeID` INT, `pSubjectID` INT,
        `pExamType` VARCHAR(30) CHARSET utf8,
        `pLectureCount` INT, `pPracticeCount` INT, `pLabCount` INT,
        `pFacultyID` INT
    )   RETURNS int(11)
    NO SQL
BEGIN
    DECLARE vChecker, vDisciplineID INT DEFAULT -1;
    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);
    SET vDisciplineID = LAST_INSERT_ID();

    INSERT INTO `disciplines_teachers`
        (DisciplineID,TeacherID)
        VALUES (vDisciplineID, pTeacherID);

    IF pExamType = 'exam' THEN
        SET vChecker = AddModuleExam(pTeacherID, vDisciplineID);
    END IF;
    SET vChecker = AddModuleExtra(pTeacherID, vDisciplineID);
    RETURN vDisciplineID;
END //



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

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

    UPDATE `disciplines`
        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
    ) 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
    # get current grade
    SELECT disciplines.GradeID INTO vCurGradeID
PavelBegunkov's avatar
PavelBegunkov committed
        FROM `disciplines`
        WHERE disciplines.ID = pDisciplineID
        LIMIT 1;
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` VARCHAR(30) CHARSET utf8
    )   RETURNS int(11)
    NO SQL
BEGIN
    DECLARE vOldExamType, vChecker, vExtraMax, vExtraID INT DEFAULT -1;
    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 `disciplines`
        INNER JOIN `modules` ON modules.Type = 'extra' AND
                                modules.DisciplineID = pDisciplineID
        WHERE disciplines.ID = pDisciplineID
        LIMIT 1;
    IF vExtraID <= 0 THEN
        RETURN -1;
    END IF;
    # check changed change exam type
    IF  (vOldExamType = pExamType) THEN
        RETURN 0;
    END IF;


    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 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 `disciplines`
        SET disciplines.ExamType = pExamType
        WHERE disciplines.ID = pDisciplineID
        LIMIT 1;
    UPDATE `submodules`
        SET submodules.MaxRate = vExtraMax
        WHERE submodules.ModuleID = vExtraID;
    RETURN 0;
END //

DROP FUNCTION IF EXISTS ChangeDisciplineHours//
CREATE FUNCTION `ChangeDisciplineHours`
    (   `pTeacherID` INT, `pDisciplineID` INT,
        `pHours` INT, `pType` INT
        # Type: 0 - Practice Hours, 1 - Lecture Hours, 2 - Lab Hours
    )   RETURNS int(11)
    NO SQL
BEGIN
    IF NOT InternalIsTeacherAuthor(pTeacherID, pDisciplineID) THEN
        RETURN -1;
    END IF;

    CASE pType
    WHEN 0 THEN
        UPDATE `disciplines`
            SET disciplines.PracticeCount = pHours
            WHERE disciplines.ID = pDisciplineID
            LIMIT 1;
    WHEN 1 THEN
        UPDATE `disciplines`
            SET disciplines.LectureCount = pHours
            WHERE disciplines.ID = pDisciplineID
            LIMIT 1;
    WHEN 2 THEN
        UPDATE `disciplines`
            SET disciplines.LabCount = pHours
            WHERE disciplines.ID = pDisciplineID
            LIMIT 1;
    END CASE;
    RETURN ROW_COUNT()-1;
END //



DROP FUNCTION IF EXISTS BindGroup//
CREATE FUNCTION `BindGroup`
    (`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
        InternalIsMapLocked(pDisciplineID)
    THEN
        RETURN -1;
    END IF;

# 2. check if study group is bound to discipline
    # TODO: extract method
    SELECT disciplines_groups.ID INTO vChecker
        FROM `disciplines_groups`
        WHERE   disciplines_groups.GroupID = pGroupID AND
                disciplines_groups.DisciplineID = pDisciplineID
        LIMIT 1;
    IF vChecker > 0 THEN
        RETURN 1;
    END IF;

# 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