Newer
Older
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//
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//
# -------------------------------------------------------------------------------------------
# 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
RETURN EXISTS(
SELECT * FROM `disciplines`
WHERE disciplines.ID = pDisciplineID AND disciplines.isLocked = 1
);
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
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 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 //
# 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 //
DROP FUNCTION IF EXISTS InternalOrderModuleTypesForSession//
CREATE FUNCTION `InternalOrderModuleTypesForSession`
(`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 = 4;
END CASE;
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
# -------------------------------------------------------------------------------------------
# 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
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
446
447
448
449
450
451
452
453
454
455
456
457
458
459
460
461
462
463
464
465
466
467
468
469
470
471
472
473
474
475
476
477
478
479
480
481
482
483
484
485
486
487
488
489
490
491
492
493
494
495
496
497
498
499
500
501
502
503
504
505
506
507
508
509
510
511
512
513
514
515
516
517
518
519
520
521
522
523
524
525
526
527
528
529
530
531
532
533
534
535
536
537
538
539
540
541
542
543
544
545
546
547
548
549
550
551
552
553
554
555
556
557
558
559
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 //
561
562
563
564
565
566
567
568
569
570
571
572
573
574
575
576
577
578
579
580
581
582
583
584
585
586
587
588
589
590
591
592
593
594
595
596
597
598
599
600
601
602
603
604
605
606
607
608
609
610
611
612
613
614
615
616
617
618
619
620
621
622
623
624
625
626
627
628
629
630
631
632
633
634
635
636
637
638
639
640
641
642
643
644
645
646
647
648
649
650
651
652
653
654
655
656
657
658
659
660
661
662
663
664
665
666
667
668
669
670
671
672
673
674
675
676
677
678
679
680
681
682
683
684
685
686
687
688
689
690
691
692
693
694
695
696
697
698
699
700
701
702
703
704
705
706
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 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
DECLARE EXIT HANDLER FOR SQLEXCEPTION RETURN -1;
IF InternalIsMapLocked(pDisciplineID) OR
NOT InternalIsTeacherAuthor(pTeacherID, pDisciplineID)
THEN
RETURN -1;
END IF;
# get current grade
SELECT disciplines.GradeID INTO vCurGradeID
FROM `disciplines`
WHERE disciplines.ID = pDisciplineID
LIMIT 1;
# delete all students
DELETE FROM `disciplines_groups`
WHERE disciplines_groups.DisciplineID = pDisciplineID;
DELETE FROM `disciplines_students`
WHERE disciplines_students.DisciplineID = pDisciplineID;
# set grade
732
733
734
735
736
737
738
739
740
741
742
743
744
745
746
747
748
749
750
751
752
753
754
755
756
757
758
759
760
761
762
763
764
765
766
767
768
769
770
771
772
773
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;
SELECT view_disciplines_results.DisciplineRateMax INTO vChecker
FROM `view_disciplines_results`
WHERE view_disciplines_results.DisciplineID = pDisciplineID
LIMIT 1;
778
779
780
781
782
783
784
785
786
787
788
789
790
791
792
793
794
795
796
797
798
799
800
801
802
803
804
805
806
807
808
809
810
811
812
813
814
815
816
817
818
819
820
821
822
823
824
825
826
827
828
829
830
831
832
833
834
835
836
837
838
839
840
841
842
843
844
845
846
847
848
849
850
851
852
853
854
855
856
857
858
859
860
861
862
863
864
865
866
867
868
869
870
871
872
873
874
875
876
877
878
879
880
881
882
883
884
885
886
887
888
889
890
891
892
893
894
895
896
897
898
899
900
901
902
903
904
905
906
907
908
909
910
911
912
913
914
915
916
917
918
919
920
921
922
923
924
925
926
927
928
929
930
931
932
933
934
935
936
937
938
939
940
941
942
943
944
945
946
947
948
949
950
951
952
953
954
955
956
957
958
959
960
961
962
963
964
965
966
967
968
969
970
971
972
973
974
975
976
977
978
979
980
981
982
983
984
985
986
987
988
989
990
991
992
993
994
995
996
997
998
999
1000
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
(SELECT students.ID
FROM `students`
WHERE students.GroupID = pGroupID
);
# 4. bind whole group
INSERT INTO `disciplines_groups`
(DisciplineID, GroupID)
VALUES (pDisciplineID, pGroupID );
RETURN 0;
END //
DROP FUNCTION IF EXISTS BindStudent//
CREATE FUNCTION `BindStudent`
( `pTeacherID` INT, `pDisciplineID` INT, `pStudentID` INT
) RETURNS int(11)
NO SQL
BEGIN
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
RETURN -1;
END IF;
# 2. check if student's group is bound yet
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;
# try to remove detached attribute
IF vInGroup > 0 THEN
DELETE FROM `disciplines_students`
WHERE disciplines_students.DisciplineID = pDisciplineID AND
disciplines_students.StudentID = pStudentID
LIMIT 1;
RETURN 0;
END IF;
# 3. try bind student
INSERT INTO `disciplines_students`
(DisciplineID, StudentID, Type)
VALUES (pDisciplineID, pStudentID, 'attach')
# update stub/ already bounded
ON DUPLICATE KEY UPDATE
disciplines_students.StudentID = disciplines_students.StudentID;
RETURN 0;
END //
DROP FUNCTION IF EXISTS UnbindGroup//
CREATE FUNCTION `UnbindGroup`
( `pTeacherID` INT, `pDisciplineID` INT, `pGroupID` INT
) RETURNS int(11)
NO SQL
BEGIN
IF NOT InternalIsTeacherAuthor(pTeacherID, pDisciplineID) OR InternalIsMapLocked(pDisciplineID)THEN
RETURN -1;
END IF;
DELETE FROM `disciplines_groups`
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);
RETURN 0;
END //
DROP FUNCTION IF EXISTS UnbindStudent//
CREATE FUNCTION `UnbindStudent`
(`pTeacherID` INT, `pDisciplineID` INT, `pStudentID` INT
) RETURNS int(11)
NO SQL
BEGIN
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 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 vInGroup > 0 THEN
INSERT INTO `disciplines_students`
(DisciplineID, StudentID, Type)
VALUES (pDisciplineID, pStudentID, 'detach');
ELSE
DELETE FROM `disciplines_students`
WHERE disciplines_students.DisciplineID = pDisciplineID AND
disciplines_students.StudentID = pStudentID
LIMIT 1;
END IF;
RETURN 0;
END //
DROP FUNCTION IF EXISTS BindTeacher//
CREATE FUNCTION `BindTeacher`
(`pTeacherID` INT, `pBindingTeacherID` INT, `pDisciplineID` INT
) RETURNS int(11)
NO SQL
BEGIN
IF NOT InternalIsTeacherAuthor(pTeacherID, pDisciplineID) THEN
RETURN -1;
END IF;
# try to insert BindingTeacher in access list
INSERT INTO `disciplines_teachers`
(DisciplineID, TeacherID)
VALUES (pDisciplineID, pBindingTeacherID)