Newer
Older
SET SQL_MODE = "NO_AUTO_VALUE_ON_ZERO";
SET time_zone = "+00:00";
/*!40101 SET @OLD_CHARACTER_SET_CLIENT=@@CHARACTER_SET_CLIENT */;
/*!40101 SET @OLD_CHARACTER_SET_RESULTS=@@CHARACTER_SET_RESULTS */;
/*!40101 SET @OLD_COLLATION_CONNECTION=@@COLLATION_CONNECTION */;
/*!40101 SET NAMES utf8 */;
DELIMITER //
DROP FUNCTION IF EXISTS getStudentsForDisciplineT//
CREATE FUNCTION getStudentsForDisciplineT (pDisciplineID INT) RETURNS INT(11)
NO SQL
BEGIN
DECLARE vSemesterID INT DEFAULT -1;
SET vSemesterID = GetDisciplineProperty(pDisciplineID, 'semester');
CREATE TEMPORARY TABLE tDisciplineStudents AS (
SELECT st.StudentID,
COALESCE(st.Type) AS 'Type'
FROM (
SELECT disciplines_students.StudentID,
disciplines_students.Type
FROM disciplines_students
WHERE disciplines_students.DisciplineID = pDisciplineID
UNION
SELECT students_groups.StudentID,
NULL AS 'Type'
FROM disciplines_groups
LEFT JOIN students_groups ON students_groups.SemesterID = vSemesterID AND
students_groups.GroupID = disciplines_groups.GroupID AND
students_groups.State <= 'outlet'
WHERE disciplines_groups.DisciplineID = pDisciplineID
GROUP BY st.StudentID
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
);
RETURN 0;
END //
DROP FUNCTION IF EXISTS getDisciplinesForStudentT//
CREATE FUNCTION getDisciplinesForStudentT(pStudentID INT, pSemesterID INT) RETURNS INT(11)
NO SQL
BEGIN
DECLARE vStudentGroup INT DEFAULT -1;
SET vStudentGroup = GetStudentGroup(pStudentID, pSemesterID);
CREATE TEMPORARY TABLE IF NOT EXISTS tStudentDisciplines AS (
SELECT disc2.DisciplineID
FROM (
SELECT disc1.DisciplineID,
COALESCE(disc1.Type) AS 'Type'
FROM (
SELECT disciplines_students.DisciplineID,
disciplines_students.Type
FROM disciplines_students
WHERE disciplines_students.StudentID = pStudentID
UNION
SELECT disciplines_groups.DisciplineID,
NULL AS 'Type'
FROM disciplines_groups
WHERE disciplines_groups.GroupID = vStudentGroup
) AS disc1
INNER JOIN disciplines ON disciplines.ID = disc1.DisciplineID
WHERE disciplines.SemesterID = pSemesterID
GROUP BY disc1.DisciplineID
) AS disc2
WHERE NOT disc2.Type <=> 'detach'
);
RETURN 0;
END //
# -------------------------------------------------------------------------------------------
# Label: semesters
# -------------------------------------------------------------------------------------------
DROP PROCEDURE IF EXISTS GetSemestersInfo//
CREATE PROCEDURE GetSemestersInfo (IN pSemesterID INT)
READS SQL DATA
SELECT semesters.* -- ID, Year, Num
FROM semesters
WHERE IF(pSemesterID != 0, semesters.ID = pSemesterID, TRUE)
ORDER BY semesters.ID DESC //
# -------------------------------------------------------------------------------------------
# Label: faculties
# -------------------------------------------------------------------------------------------
DROP PROCEDURE IF EXISTS GetFaculties//
CREATE PROCEDURE GetFaculties ()
READS SQL DATA
SELECT faculties.* -- ID, Abbr, Name
FROM faculties
ORDER BY faculties.Name ASC //
# -------------------------------------------------------------------------------------------
# Label: departments
# -------------------------------------------------------------------------------------------
DROP PROCEDURE IF EXISTS GetDepartments//
CREATE PROCEDURE GetDepartments (IN pFacultyID INT)
READS SQL DATA
BEGIN
IF pFacultyID <=> 0 THEN
SELECT departments.* FROM departments
ORDER BY departments.Name ASC;
ELSE
SELECT departments.* -- ID, Name, FacultyID
FROM departments
WHERE departments.FacultyID = pFacultyID
ORDER BY departments.Name ASC;
END IF;
END //
# -------------------------------------------------------------------------------------------
# Label: specializations
# -------------------------------------------------------------------------------------------
DROP PROCEDURE IF EXISTS GetSpecializations//
CREATE PROCEDURE GetSpecializations (IN pFacultyID INT)
READS SQL DATA
SELECT specializations.* -- ID, Name, Abbr, FacultyID
FROM specializations
WHERE specializations.FacultyID = pFacultyID
ORDER BY subjects.Name ASC //
# -------------------------------------------------------------------------------------------
# Label: job positions
# -------------------------------------------------------------------------------------------
DROP PROCEDURE IF EXISTS GetJobPositions//
CREATE PROCEDURE GetJobPositions ()
READS SQL DATA
SELECT job_positions.* -- ID, Name
FROM job_positions
ORDER BY job_positions.Name //
# -------------------------------------------------------------------------------------------
# Label: grades
# -------------------------------------------------------------------------------------------
DROP PROCEDURE IF EXISTS GetGrades//
CREATE PROCEDURE GetGrades ()
READS SQL DATA
SELECT grades.* -- ID, Num, Degree
FROM grades
ORDER BY grades.ID //
# -------------------------------------------------------------------------------------------
# Label: study groups
# -------------------------------------------------------------------------------------------
DROP PROCEDURE IF EXISTS GetGroups//
CREATE PROCEDURE GetGroups (
IN pGradeID INT,
IN pFacultyID INT)
READS SQL DATA
BEGIN
PavelBegunkov
committed
SELECT view_groups_reduced.GroupID AS 'ID',
view_groups_reduced.GroupNum,
view_groups_reduced.SpecID,
view_groups_reduced.SpecName,
view_groups_reduced.SpecAbbr
FROM view_groups_reduced
WHERE view_groups_reduced.GradeID = pGradeID AND
view_groups_reduced.FacultyID = pFacultyID
ORDER BY view_groups_reduced.GroupNum ASC;
END //
# get all groups, include attached student's groups
DROP PROCEDURE IF EXISTS GetGroupsForDisciplineAll//
CREATE PROCEDURE GetGroupsForDisciplineAll (IN pDisciplineID INT)
BEGIN
PavelBegunkov
committed
DECLARE vSemesterID, vYear INT DEFAULT -1;
SET vSemesterID = GetDisciplineProperty(pDisciplineID, 'semester');
PavelBegunkov
committed
SET vYear = (SELECT Year from semesters where semesters.ID = vSemesterID);
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
# general + attached
CREATE TEMPORARY TABLE IF NOT EXISTS tGroup AS (
SELECT tGroup1.GroupID
FROM (
SELECT students_groups.GroupID
FROM disciplines_students
INNER JOIN students_groups ON students_groups.StudentID = disciplines_students.StudentID AND
students_groups.SemesterID = vSemesterID AND
students_groups.State <= 'outlet'
WHERE disciplines_students.DisciplineID = pDisciplineID AND
disciplines_students.Type = 'attach'
UNION
SELECT disciplines_groups.GroupID
FROM disciplines_groups
WHERE disciplines_groups.DisciplineID = pDisciplineID
) tGroup1
);
SELECT view_groups.GroupID AS 'ID',
view_groups.GroupNum,
view_groups.GradeID,
view_groups.GradeNum,
view_groups.Degree,
view_groups.SpecID,
view_groups.SpecName,
view_groups.SpecAbbr
FROM tGroup
PavelBegunkov
committed
INNER JOIN view_groups ON tGroup.GroupID = view_groups.GroupID AND view_groups.Year = vYear
ORDER BY view_groups.GradeID ASC, view_groups.GroupID ASC;
END //
# get all general study groups, that takes this course
DROP PROCEDURE IF EXISTS GetGroupsForDiscipline//
CREATE PROCEDURE GetGroupsForDiscipline (IN pDisciplineID INT)
READS SQL DATA
BEGIN
SELECT view_groups.GroupID AS 'ID',
view_groups.GroupNum,
view_groups.GradeID,
view_groups.GradeNum,
view_groups.Degree,
view_groups.SpecID,
view_groups.SpecName,
view_groups.SpecAbbr
FROM disciplines_groups
PavelBegunkov
committed
INNER JOIN disciplines ON disciplines_groups.DisciplineID = disciplines.ID
INNER JOIN semesters ON disciplines.SemesterID = semesters.ID
INNER JOIN view_groups ON disciplines_groups.GroupID = view_groups.GroupID
PavelBegunkov
committed
WHERE disciplines_groups.DisciplineID = pDisciplineID
AND view_groups.Year = semesters.Year
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
ORDER BY view_groups.GradeID ASC, view_groups.GroupID ASC;
END //
# -------------------------------------------------------------------------------------------
# Label: subjects
# -------------------------------------------------------------------------------------------
DROP PROCEDURE IF EXISTS GetSubjects//
CREATE PROCEDURE GetSubjects (IN pFacultyID INT)
READS SQL DATA
BEGIN
SELECT subjects.ID,
subjects.Name AS 'Title',
subjects.Abbr
FROM subjects_faculties
INNER JOIN subjects ON subjects_faculties.SubjectID = subjects.ID
WHERE subjects_faculties.FacultyID = pFacultyID
ORDER BY subjects.Name ASC;
END //
# -------------------------------------------------------------------------------------------
# Label: accounts
# -------------------------------------------------------------------------------------------
DROP PROCEDURE IF EXISTS GetFullInfo//
CREATE PROCEDURE GetFullInfo (
IN pUserID INT,
IN pSemesterID INT)
READS SQL DATA
BEGIN
DECLARE vAccountType enum('student', 'teacher');
SELECT user_roles.Type INTO vAccountType
FROM accounts
INNER JOIN user_roles ON accounts.UserRoleID = user_roles.ID
WHERE accounts.ID = pUserID
LIMIT 1;
# type 1: student
# 2: teacher
IF vAccountType = 'student' THEN
SELECT
# personal info
students.ID as 'StudentID',
# group info
-- GradeID, GradeNum, GroupID, GroupNum, GroupName, Degree,
-- SpecID, SpecName, SpecAbbr, FacultyID, FacultyName, FacultyAbbr,
PavelBegunkov
committed
view_groups_reduced.*,
students_groups.SemesterID,
# account info
accounts.ID,
accounts.Login,
accounts.EMail,
Artem Konenko
committed
accounts.LastName,
accounts.FirstName,
accounts.SecondName,
user_roles.Type,
user_roles.RoleName AS 'Role',
user_roles.Mark AS 'RoleMark',
accounts.IsEnabled,
accounts.ActivationCode AS 'Code',
accounts.UserAgent
FROM students
INNER JOIN accounts ON accounts.ID = students.AccountID
INNER JOIN user_roles ON user_roles.ID = accounts.UserRoleID
LEFT JOIN students_groups ON students.ID = students_groups.StudentID
PavelBegunkov
committed
LEFT JOIN view_groups_reduced ON view_groups_reduced.GroupID = students_groups.GroupID
WHERE students.AccountID = pUserID
ORDER BY students_groups.SemesterID <=> pSemesterID DESC
LIMIT 1;
ELSE
SELECT # teacher info
view_teachers.TeacherID,
view_teachers.DepID,
view_teachers.DepName,
view_teachers.JobPositionName,
view_teachers.FacultyID,
view_teachers.FacultyName,
view_teachers.FacultyAbbr,
# account info
accounts.ID,
accounts.Login,
accounts.EMail,
Artem Konenko
committed
accounts.LastName,
accounts.FirstName,
accounts.SecondName,
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
user_roles.Type,
user_roles.RoleName AS 'Role',
user_roles.Mark AS 'RoleMark',
accounts.IsEnabled,
accounts.ActivationCode AS 'Code',
accounts.UserAgent
FROM view_teachers
INNER JOIN accounts ON accounts.ID = view_teachers.AccountID
INNER JOIN user_roles ON user_roles.ID = accounts.UserRoleID
WHERE view_teachers.AccountID = pUserID
LIMIT 1;
END IF;
END //
# -------------------------------------------------------------------------------------------
# Label: teachers
# -------------------------------------------------------------------------------------------
DROP PROCEDURE IF EXISTS GetTeachers//
CREATE PROCEDURE GetTeachers (
IN pFacultyID INT,
IN pDepartmentID INT)
READS SQL DATA
BEGIN
SELECT view_teachers.TeacherID AS 'ID',
view_teachers.LastName,
view_teachers.FirstName,
view_teachers.SecondName,
view_teachers.AccountID,
view_teachers.JobPositionName,
view_teachers.DepID,
view_teachers.DepName
FROM view_teachers
WHERE
CASE WHEN pFacultyID != 0 THEN view_teachers.FacultyID = pFacultyID ELSE TRUE END AND
CASE WHEN pDepartmentID != 0 THEN view_teachers.DepID = pDepartmentID ELSE TRUE END
ORDER BY view_teachers.LastName ASC,
view_teachers.FirstName ASC;
END //
# get teachers, that teach course
DROP PROCEDURE IF EXISTS GetTeachersForDiscipline//
CREATE PROCEDURE GetTeachersForDiscipline(IN pDisciplineID INT)
READS SQL DATA
BEGIN
DECLARE vAuthorID INT DEFAULT -1;
SET vAuthorID = GetDisciplineProperty(pDisciplineID, 'author');
SELECT view_teachers.TeacherID AS 'ID',
view_teachers.LastName,
view_teachers.FirstName,
view_teachers.SecondName,
view_teachers.JobPositionID,
view_teachers.JobPositionName,
view_teachers.DepID,
view_teachers.DepName,
view_teachers.FacultyID,
view_teachers.FacultyAbbr,
( view_teachers.TeacherID = vAuthorID ) AS 'IsAuthor'
FROM disciplines_teachers
INNER JOIN view_teachers ON view_teachers.TeacherID = disciplines_teachers.TeacherID
WHERE disciplines_teachers.DisciplineID = pDisciplineID
ORDER BY view_teachers.TeacherID = vAuthorID DESC,
view_teachers.LastName ASC,
view_teachers.FirstName ASC;
END //
DROP PROCEDURE IF EXISTS GetTeachersListForStudent//
CREATE PROCEDURE GetTeachersListForStudent (
IN pStudentID INT,
IN pSemesterID INT,
IN pLoadAll INT)
BEGIN
DECLARE vRes, vStudentGroup INT DEFAULT -1;
SET vStudentGroup = GetStudentGroup(pStudentID, pSemesterID);
DROP TABLE IF EXISTS tStudentDisciplines;
SET vRes = getDisciplinesForStudentT(pStudentID, pSemesterID);
SELECT tStudentDisciplines.DisciplineID,
teachers.ID AS 'TeacherID',
Artem Konenko
committed
accounts.LastName,
accounts.FirstName,
accounts.SecondName
FROM tStudentDisciplines
INNER JOIN disciplines ON disciplines.ID = tStudentDisciplines.DisciplineID
LEFT JOIN disciplines_teachers ON disciplines_teachers.DisciplineID = tStudentDisciplines.DisciplineID
INNER JOIN teachers ON teachers.ID = disciplines_teachers.TeacherID
Artem Konenko
committed
INNER JOIN accounts ON teachers.AccountID = accounts.ID
WHERE pLoadAll OR disciplines.Subtype IS NULL
ORDER BY tStudentDisciplines.DisciplineID ASC,
Artem Konenko
committed
accounts.LastName ASC,
accounts.FirstName ASC;
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
560
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
END //
# get teachers, that don't teach course
DROP PROCEDURE IF EXISTS SearchTeachers//
CREATE PROCEDURE SearchTeachers (
IN pFacultyID INT,
IN pDepartmentID INT,
IN pWord1 VARCHAR(100) CHARSET utf8,
IN pWord2 VARCHAR(100) CHARSET utf8,
IN pWord3 VARCHAR(100) CHARSET utf8,
IN pDisciplineID INT)
BEGIN
DECLARE vWord1, vWord2, vWord3 VARCHAR(102) CHARSET utf8;
DECLARE vAuthorID INT DEFAULT -1;
SET vWord1 = CONCAT('%', pWord1, '%');
SET vWord2 = CONCAT('%', pWord2, '%');
SET vWord3 = CONCAT('%', pWord3, '%');
SET vAuthorID = GetDisciplineProperty(pDisciplineID, 'author');
DROP TABLE IF EXISTS tDiscTeachers;
CREATE TEMPORARY TABLE tDiscTeachers AS (
SELECT disciplines_teachers.TeacherID
FROM disciplines_teachers
WHERE disciplines_teachers.DisciplineID <=> pDisciplineID
);
SELECT tTeachers.TeacherID AS 'ID',
tTeachers.LastName,
tTeachers.FirstName,
tTeachers.SecondName,
tTeachers.JobPositionName,
tTeachers.DepID,
tTeachers.DepName,
( tTeachers.TeacherID = vAuthorID ) AS 'IsAuthor'
FROM view_teachers AS tTeachers
WHERE tTeachers.FacultyID = pFacultyID AND
CASE WHEN pDepartmentID != 0 THEN tTeachers.DepID = pDepartmentID ELSE TRUE END AND
NOT EXISTS (
SELECT * FROM tDiscTeachers
WHERE tDiscTeachers.TeacherID = tTeachers.TeacherID
LIMIT 1
) AND
CASE WHEN pWord1 != '' AND
(@full := CONCAT(tTeachers.LastName, ' ', tTeachers.FirstName, ' ', tTeachers.SecondName)) != '' THEN
@full LIKE vWord1 AND
@full LIKE vWord2 AND
@full LIKE vWord3
ELSE TRUE
END
ORDER BY tTeachers.FacultyID ASC,
tTeachers.DepName ASC,
tTeachers.LastName ASC,
tTeachers.FirstName ASC;
END //
# -------------------------------------------------------------------------------------------
# Label: students
# -------------------------------------------------------------------------------------------
DROP PROCEDURE IF EXISTS GetStudents//
CREATE PROCEDURE GetStudents (
IN pFacultyID INT,
IN pGradeID INT,
IN pGroupID INT,
IN pSemesterID INT,
IN pWord1 VARCHAR(100) CHARSET utf8,
IN pWord2 VARCHAR(100) CHARSET utf8,
IN pWord3 VARCHAR(100) CHARSET utf8)
BEGIN
DECLARE vWord1, vWord2, vWord3 VARCHAR(102) CHARSET utf8;
SET vWord1 = CONCAT('%', pWord1, '%');
SET vWord2 = CONCAT('%', pWord2, '%');
SET vWord3 = CONCAT('%', pWord3, '%');
SELECT view_students.StudentID AS 'ID',
view_students.LastName,
view_students.FirstName,
view_students.SecondName,
view_students.AccountID,
view_students.GradeID,
view_students.GradeNum,
view_students.Degree,
view_students.GroupID,
view_students.GroupNum
FROM view_students
WHERE view_students.SemesterID = pSemesterID AND
CASE WHEN pFacultyID != 0 THEN view_students.FacultyID = pFacultyID ELSE TRUE END AND
CASE WHEN pGradeID != 0 THEN view_students.GradeID = pGradeID ELSE TRUE END AND
CASE WHEN pGroupID != 0 THEN view_students.GroupID = pGroupID ELSE TRUE END AND
CASE WHEN pWord1 != '' AND
(@full := CONCAT(view_students.LastName, ' ', view_students.FirstName, ' ', view_students.SecondName)) != '' THEN
@full LIKE vWord1 AND
@full LIKE vWord2 AND
@full LIKE vWord3
ELSE TRUE
END
ORDER BY view_students.LastName ASC,
view_students.FirstName ASC;
END //
# not in general groups, not attached
DROP PROCEDURE IF EXISTS SearchStudents//
CREATE PROCEDURE SearchStudents (
IN pGradeID INT,
IN pGroupID INT,
IN pFacultyID INT,
IN pFullName VARCHAR(100) CHARSET utf8,
IN pDisciplineID INT)
BEGIN
DECLARE vSemesterID, vRes INT DEFAULT -1;
DECLARE vFullNameReg VARCHAR(102) CHARSET utf8;
SET vSemesterID = GetDisciplineProperty(pDisciplineID, 'semester');
SET vFullNameReg = CONCAT('%', pFullName, '%');
DROP TABLE IF EXISTS tDisciplineStudents;
SET vRes = getStudentsForDisciplineT(pDisciplineID);
SELECT view_students.StudentID AS 'ID',
view_students.LastName,
view_students.FirstName,
view_students.SecondName,
view_students.GradeID,
view_students.GradeNum,
view_students.Degree,
view_students.GroupID,
view_students.GroupNum
FROM view_students
LEFT JOIN tDisciplineStudents ON tDisciplineStudents.StudentID = view_students.StudentID
WHERE view_students.SemesterID = vSemesterID AND
view_students.FacultyID = pFacultyID AND
view_students.GradeID = pGradeID AND
(pGroupID = 0 OR view_students.GroupID = pGroupID) AND
tDisciplineStudents.StudentID IS NULL AND
CASE WHEN pFullName != '' THEN
CONCAT(view_students.LastName, ' ', view_students.FirstName, ' ', view_students.SecondName) LIKE vFullNameReg
ELSE TRUE END
ORDER BY view_students.GradeID ASC,
view_students.GroupID ASC,
view_students.LastName ASC,
view_students.FirstName ASC;
END //
# in general groups, attached or detached
DROP PROCEDURE IF EXISTS GetStudentsForDiscipline//
CREATE PROCEDURE GetStudentsForDiscipline (
IN pDisciplineID INT)
BEGIN
DECLARE vSemesterID, vRes INT DEFAULT -1;
SET vSemesterID = GetDisciplineProperty(pDisciplineID, 'semester');
DROP TABLE IF EXISTS tDisciplineStudents;
SET vRes = getStudentsForDisciplineT(pDisciplineID);
SELECT view_students.StudentID AS 'ID',
view_students.LastName,
view_students.FirstName,
view_students.SecondName,
view_students.GradeID,
view_students.GradeNum,
view_students.Degree,
view_students.GroupID,
view_students.GroupNum,
tDisciplineStudents.Type AS 'AttachType'
FROM tDisciplineStudents
INNER JOIN view_students ON view_students.StudentID = tDisciplineStudents.StudentID AND
view_students.SemesterID = vSemesterID
ORDER BY tDisciplineStudents.Type <=> 'attach' ASC,
view_students.GradeID ASC,
view_students.GroupNum ASC,
view_students.LastName ASC,
view_students.FirstName ASC;
END //
# in general groups + attached
DROP PROCEDURE IF EXISTS GetStudentsForRating//
CREATE PROCEDURE GetStudentsForRating (
IN pDisciplineID INT)
BEGIN
DECLARE vSemesterID, vRes INT DEFAULT -1;
SET vSemesterID = GetDisciplineProperty(pDisciplineID, 'semester');
DROP TABLE IF EXISTS tDisciplineStudents;
SET vRes = getStudentsForDisciplineT(pDisciplineID);
SELECT view_students.StudentID AS 'ID',
view_students.LastName,
view_students.FirstName,
view_students.SecondName,
view_students.GradeID,
view_students.GradeNum,
view_students.Degree,
view_students.GroupID,
view_students.GroupNum,
( tDisciplineStudents.Type IS NOT NULL ) AS 'IsAttached'
FROM tDisciplineStudents
INNER JOIN view_students ON view_students.StudentID = tDisciplineStudents.StudentID AND
view_students.SemesterID = vSemesterID
WHERE NOT tDisciplineStudents.Type <=> 'detach'
ORDER BY view_students.GradeID ASC,
view_students.GroupNum ASC,
view_students.LastName ASC,
view_students.FirstName ASC;
END //
# -------------------------------------------------------------------------------------------
# Label: disciplines
# -------------------------------------------------------------------------------------------
DROP PROCEDURE IF EXISTS GetDisciplineInfo//
DROP PROCEDURE IF EXISTS Discipline_GetInfo//
CREATE PROCEDURE Discipline_GetInfo (IN pDisciplineID INT)
READS SQL DATA
BEGIN
DECLARE vIsBonus BOOLEAN;
SET vIsBonus = EXISTS(
SELECT * FROM modules
WHERE modules.DisciplineID = pDisciplineID AND
modules.Type = 'bonus'
LIMIT 1
);
SELECT
view_disciplines.DisciplineID AS 'ID',
view_disciplines.AuthorID,
view_disciplines.GradeID,
view_disciplines.GradeNum,
view_disciplines.Degree,
view_disciplines.ExamType AS 'Type',
view_disciplines.LectureCount AS 'Lectures',
view_disciplines.PracticeCount AS 'Practice',
view_disciplines.LabCount AS 'Labs',
view_disciplines.SemesterID,
view_disciplines.SubjectID,
view_disciplines.SubjectName,
view_disciplines.SubjectAbbr,
view_disciplines.FacultyID,
view_disciplines.FacultyName,
view_disciplines.IsLocked,
view_disciplines.Milestone,
view_disciplines.Subtype,
view_disciplines.CompoundDiscID,
Artem Konenko
committed
(view_disciplines.MaxRate = 100) AS 'IsMapCreated',
vIsBonus AS 'IsBonus',
semesters.Num AS 'semesterNum', # TODO: Camelize
semesters.Year AS 'semesterYear'
FROM view_disciplines
INNER JOIN semesters ON semesters.ID = view_disciplines.SemesterID
WHERE view_disciplines.DisciplineID = pDisciplineID
LIMIT 1;
END //
# это обертка процедуры Discipline_GetInfo для случая, когда передается SubmoduleID
DROP PROCEDURE IF EXISTS Discipline_GetInfoBySubmodule //
CREATE PROCEDURE Discipline_GetInfoBySubmodule (
pSubmoduleID INT
)
READS SQL DATA
BEGIN
DECLARE vDisciplineID INT DEFAULT -1;
SELECT modules.DisciplineID
INTO vDisciplineID
FROM submodules
INNER JOIN modules ON submodules.ModuleID = modules.ID
WHERE submodules.ID = pSubmoduleID
LIMIT 1;
CALL Discipline_GetInfo(vDisciplineID);
END //
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
707
708
709
710
711
712
713
714
715
716
717
# all disciplines for faculty in current semester
DROP PROCEDURE IF EXISTS GetDisciplines//
CREATE PROCEDURE GetDisciplines (
IN pFacultyID INT,
IN pSemesterID INT)
READS SQL DATA
BEGIN
SELECT view_disciplines.DisciplineID AS 'ID',
view_disciplines.SubjectID,
view_disciplines.SubjectName,
view_disciplines.ExamType AS 'Type',
(view_disciplines.MaxRate = 100) AS 'isMapCreated'
FROM view_disciplines
WHERE view_disciplines.SemesterID = pSemesterID AND
view_disciplines.FacultyID = pFacultyID
ORDER BY view_disciplines.SubjectName ASC;
END //
DROP PROCEDURE IF EXISTS GetCompoundDisciplinesForGrade//
CREATE PROCEDURE GetCompoundDisciplinesForGrade (IN pGradeID INT)
READS SQL DATA
BEGIN
SELECT compound_disciplines.ID,
compound_disciplines.Name
FROM compound_disciplines
WHERE compound_disciplines.GradeID = pGradeID;
END //
# processed format of output (after desequentialization)
# { discipline1 {group1, group2, ...}, discipline2 {groupN, ...}, ... }
DROP PROCEDURE IF EXISTS GetDisciplinesForTeacher//
CREATE PROCEDURE GetDisciplinesForTeacher (
IN pTeacherID INT,
IN pSemesterID INT)
READS SQL DATA
BEGIN
SELECT DISTINCT view_disciplines.DisciplineID AS 'ID',
PavelBegunkov
committed
view_disciplines.ExamType AS 'Type',
view_disciplines.Subtype,
view_disciplines.GradeID,
view_disciplines.GradeNum,
view_disciplines.Degree,
view_groups.GroupID,
view_groups.GroupNum,
view_groups.GroupName,
view_disciplines.SubjectID,
view_disciplines.SubjectName,
view_disciplines.AuthorID,
view_disciplines.IsLocked AS 'IsLocked', -- bodging, db schema remembered lowerCase
(view_disciplines.MaxRate = 100) AS 'IsMapCreated'
FROM disciplines_teachers
INNER JOIN view_disciplines ON disciplines_teachers.DisciplineID = view_disciplines.DisciplineID
PavelBegunkov
committed
INNER JOIN semesters ON semesters.ID = view_disciplines.SemesterID
LEFT JOIN disciplines_groups ON disciplines_groups.DisciplineID = disciplines_teachers.DisciplineID
LEFT JOIN view_groups ON view_groups.GroupID = disciplines_groups.GroupID AND view_groups.Year = semesters.Year
WHERE disciplines_teachers.TeacherID = pTeacherID AND view_disciplines.SemesterID = pSemesterID
ORDER BY view_disciplines.GradeID ASC,
view_disciplines.SubjectName ASC,
view_disciplines.DisciplineID ASC,
view_groups.GroupNum ASC;
END //
# get all disciplines, that student take.
DROP PROCEDURE IF EXISTS GetDisciplinesForStudent//
CREATE PROCEDURE GetDisciplinesForStudent (
IN pStudentID INT,
IN pSemesterID INT)
READS SQL DATA
BEGIN
DECLARE vRes INT DEFAULT -1;
DROP TABLE IF EXISTS tStudentDisciplines;
SET vRes = getDisciplinesForStudentT(pStudentID, pSemesterID);
# only Cthulhu knows, what happened here
SELECT view_disciplines.DisciplineID AS 'ID',
view_disciplines.SubjectID,
view_disciplines.SubjectName,
view_disciplines.ExamType AS 'Type',
view_disciplines.Subtype,
Artem Konenko
committed
accounts.LastName,
accounts.FirstName,
accounts.SecondName,
763
764
765
766
767
768
769
770
771
772
773
774
775
776
777
778
779
780
781
782
783
784
785
786
787
788
789
790
791
( tDR.RateExam + tDR.RateMExam ) AS 'Rate',
( tDR.MaxRegularRate + tDR.MaxExamRate ) AS 'MaxCurrentRate'
FROM (
SELECT tRating.DisciplineID,
SUM(
IF( tRating.SubmoduleIsUsed AND tRating.ModuleType <=> 'regular',
tRating.SubmoduleRate, 0)
) AS 'MaxRegularRate',
MAX(
IF( tRating.SubmoduleIsUsed AND tRating.ModuleType <=> 'exam',
tRating.SubmoduleRate, 0)
) AS 'MaxExamRate',
SUM(IF(NOT tRating.ModuleType <=> 'exam', tRating.Rate, 0)) AS 'RateMExam',
MAX(IF(tRating.ModuleType <=> 'exam' AND tRating.Rate IS NOT NULL, tRating.Rate, 0)) AS 'RateExam'
FROM (
SELECT tStudentDisciplines.DisciplineID,
vr.SubmoduleRate,
vr.ModuleType,
rt.Rate,
vr.SubmoduleIsUsed
FROM tStudentDisciplines as tStudentDisciplines
LEFT JOIN view_roadmap AS vr ON vr.DisciplineID = tStudentDisciplines.DisciplineID
LEFT JOIN rating_table AS rt ON rt.StudentID = pStudentID AND
rt.SubmoduleID = vr.SubmoduleID
) AS tRating
GROUP BY tRating.DisciplineID
) AS tDR
INNER JOIN view_disciplines ON view_disciplines.DisciplineID = tDR.DisciplineID
INNER JOIN teachers ON teachers.ID = view_disciplines.AuthorID
Artem Konenko
committed
INNER JOIN accounts ON teachers.AccountID = accounts.ID
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
ORDER BY view_disciplines.ExamType ASC, view_disciplines.SubjectName ASC;
END //
# get all disciplines for group, including disciplines, where students have attached status
DROP PROCEDURE IF EXISTS GetDisciplinesForGroup//
CREATE PROCEDURE GetDisciplinesForGroup (
IN pGroupID INT,
IN pSemesterID INT)
READS SQL DATA
BEGIN
# Get all attached groups for disc
DROP TABLE IF EXISTS tDisc;
CREATE TEMPORARY TABLE tDisc AS (
SELECT tTemp.DisciplineID
FROM (
SELECT disciplines_groups.DisciplineID
FROM disciplines_groups
WHERE disciplines_groups.GroupID = pGroupID
UNION
SELECT DISTINCT disciplines_students.DisciplineID
FROM students_groups
LEFT JOIN disciplines_students ON disciplines_students.StudentID = students_groups.StudentID
WHERE students_groups.GroupID = pGroupID AND
students_groups.SemesterID = pSemesterID AND
students_groups.State <= 'outlet' AND
disciplines_students.Type <=> 'attach'
) AS tTemp
);
SELECT tDisc.DisciplineID AS 'ID',
view_disciplines.SubjectName,
view_disciplines.Subtype,
view_disciplines.ExamType AS 'Type',
view_disciplines.CompoundDiscID,
view_disciplines.CompoundDiscName,
view_disciplines.CurRate,
view_disciplines.MaxRate
FROM tDisc
INNER JOIN view_disciplines ON tDisc.DisciplineID = view_disciplines.DisciplineID
WHERE view_disciplines.SemesterID = pSemesterID;
END //
# -------------------------------------------------------------------------------------------
# Label: rating
# -------------------------------------------------------------------------------------------
# TODO: merge with GetRatesForGroupByStage
DROP PROCEDURE IF EXISTS GetRatesForGroup//
CREATE PROCEDURE GetRatesForGroup (
IN pDisciplineID INT,
IN pGroupID INT)
BEGIN
DECLARE vInGeneralGroup BOOLEAN DEFAULT FALSE;
DECLARE vSemesterID INT DEFAULT -1;
SET vSemesterID = GetDisciplineProperty(pDisciplineID, 'semester');
SET vInGeneralGroup = EXISTS(
SELECT * FROM disciplines_groups
WHERE disciplines_groups.DisciplineID = pDisciplineID AND
disciplines_groups.GroupID = pGroupID
LIMIT 1
);
DROP TABLE IF EXISTS tStudents;
CREATE TEMPORARY TABLE tStudents AS (
SELECT students_groups.StudentID
FROM students_groups
LEFT JOIN disciplines_students ON disciplines_students.DisciplineID = pDisciplineID AND
disciplines_students.StudentID = students_groups.StudentID
WHERE students_groups.SemesterID = vSemesterID AND
students_groups.State <= 'outlet' AND # actual students
students_groups.GroupID = pGroupID AND
CASE WHEN vInGeneralGroup THEN
NOT disciplines_students.Type <=> 'detach' # not detached
ELSE
disciplines_students.Type <=> 'attach' # is attached
END
);
DROP TABLE IF EXISTS vRoadMap;
CREATE TEMPORARY TABLE vRoadMap AS (
SELECT view_roadmap.SubmoduleID,
view_roadmap.ModuleType AS 'Type'
FROM view_roadmap
WHERE view_roadmap.DisciplineID = pDisciplineID
);
SELECT students.ID,
Artem Konenko
committed
accounts.LastName,
accounts.FirstName,
accounts.SecondName,
vRates.RateRegular AS 'intermediate',
vRates.RateBonus AS 'bonus',
vRates.RateExam AS 'exam'
FROM (
SELECT tStudents.StudentID,
SUM(IF(vRoadMap.Type = 'regular', rt.Rate, 0)) AS 'RateRegular',
SUM(IF(vRoadMap.Type = 'extra', rt.Rate, 0)) AS 'RateExtra',
SUM(IF(vRoadMap.Type = 'bonus', rt.Rate, 0)) AS 'RateBonus',
MAX(IF(vRoadMap.Type = 'exam', rt.Rate, 0)) AS 'RateExam'
FROM tStudents
CROSS JOIN vRoadMap
LEFT JOIN rating_table as rt ON rt.StudentID = tStudents.StudentID AND
rt.SubmoduleID = vRoadMap.SubmoduleID
GROUP BY tStudents.StudentID
) vRates
INNER JOIN students ON students.ID = vRates.StudentID
Artem Konenko
committed
LEFT JOIN accounts ON students.AccountID = accounts.ID
ORDER BY CONCAT(accounts.LastName, accounts.FirstName, accounts.SecondName) ASC, students.ID ASC;
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
END //
# TODO: merge with GetRatesForGroupByStage
DROP PROCEDURE IF EXISTS GetRatesForGroupAll//
CREATE PROCEDURE GetRatesForGroupAll (
IN pGroupID INT,
IN pSemesterID INT)
BEGIN
DROP TABLE IF EXISTS tDisc;
CREATE TEMPORARY TABLE tDisc AS (
SELECT tTemp.DisciplineID
FROM (
SELECT disciplines_groups.DisciplineID
FROM disciplines_groups
WHERE disciplines_groups.GroupID = pGroupID
UNION
SELECT DISTINCT disciplines_students.DisciplineID
FROM students_groups
LEFT JOIN disciplines_students ON disciplines_students.StudentID = students_groups.StudentID
WHERE students_groups.GroupID = pGroupID AND
students_groups.State <= 'outlet' AND
disciplines_students.Type <=> 'attach'
) AS tTemp
);
DROP TABLE IF EXISTS tStudents;
CREATE TEMPORARY TABLE tStudents AS (
SELECT students_groups.StudentID
FROM students_groups
WHERE students_groups.GroupID = pGroupID
and students_groups.SemesterID = pSemesterID
);
DROP TABLE IF EXISTS vRoadMap;
CREATE TEMPORARY TABLE vRoadMap AS (
SELECT tDisc.DisciplineID as 'DisciplineID',
view_roadmap.ModuleType as 'Type',
view_roadmap.SubmoduleID
FROM tDisc
LEFT JOIN view_roadmap ON view_roadmap.DisciplineID = tDisc.DisciplineID
);
SELECT vRates.StudentID as 'StudentID',
vRates.DisciplineID as 'DisciplineID',
disciplines.CompoundDiscID,
vRates.RateRegular AS 'intermediate',
vRates.RateBonus AS 'bonus',
vRates.RateExtra AS 'extra',
vRates.RateExam AS 'exam',
vRates.CntExam AS 'examCnt'
FROM (
SELECT tStudents.StudentID,
vRoadMap.DisciplineID,
SUM(IF(vRoadMap.Type = 'regular', rt.Rate, 0)) AS 'RateRegular',
SUM(IF(vRoadMap.Type = 'extra', rt.Rate, 0)) AS 'RateExtra',
SUM(IF(vRoadMap.Type = 'bonus', rt.Rate, 0)) AS 'RateBonus',
MAX(IF(vRoadMap.Type = 'exam', rt.Rate, 0)) AS 'RateExam',
SUM(IF(vRoadMap.Type = 'exam', 1, 0)) AS 'CntExam'
FROM tStudents
CROSS JOIN vRoadMap
LEFT JOIN rating_table as rt ON rt.StudentID = tStudents.StudentID AND
rt.SubmoduleID = vRoadMap.SubmoduleID
WHERE rt.Rate IS NOT NULL
GROUP BY tStudents.StudentID, vRoadMap.DisciplineID
) vRates
INNER JOIN students ON students.ID = vRates.StudentID
Artem Konenko
committed
INNER JOIN accounts ON students.AccountID = accounts.ID
INNER JOIN disciplines ON disciplines.id = vRates.DisciplineID
Artem Konenko
committed
ORDER BY CONCAT(accounts.LastName, accounts.FirstName, accounts.SecondName) ASC,
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
vRates.DisciplineID ASC;
END //
DROP PROCEDURE IF EXISTS GetRatesForGroupByStage//
CREATE PROCEDURE GetRatesForGroupByStage (
IN pDisciplineID INT,
IN pGroupID INT,
IN pMilestone INT)
BEGIN
DECLARE vSemesterID, vGroupID INT DEFAULT -1;
DECLARE vInGeneralGroup BOOL DEFAULT FALSE;
SET vSemesterID = GetDisciplineProperty(pDisciplineID, 'semester');
DROP TABLE IF EXISTS tStudents;
CREATE TEMPORARY TABLE tStudents (
StudentID INT NOT NULL
);
# check that group attached to discipline. Otherwise vGroupID = -1;
SET vInGeneralGroup = EXISTS(
SELECT * FROM disciplines_groups
WHERE disciplines_groups.DisciplineID = pDisciplineID AND
disciplines_groups.GroupID = pGroupID
LIMIT 1
);
DROP TABLE IF EXISTS tStudents;
CREATE TEMPORARY TABLE tStudents AS (