diff --git a/db/StoredFunctions.sql b/db/StoredFunctions.sql
index ef998348013b91819a633e0c87696f1c66d0174c..38044fe85d159b7b57a41ad2bc73dd1b6e4894ca 100644
--- a/db/StoredFunctions.sql
+++ b/db/StoredFunctions.sql
@@ -838,7 +838,7 @@ BEGIN
     #    346 is used as a default id for scientific courseworks.
     #    This constant is duplicated in Model_Helper_CourseWorkBuilder
 
-    IF pSubtype IS NULL THEN
+    IF pSubtype IS NOT NULL THEN
         SET pSubjectID = 346;
     END IF;
 
@@ -2303,4 +2303,4 @@ BEGIN
     RETURN LAST_INSERT_ID();
 END //
 
-DELIMITER ;
\ No newline at end of file
+DELIMITER ;
diff --git a/db/StoredProcedures.sql b/db/StoredProcedures.sql
index 9a43f31a01e48da0b7e0dea32a93d06ae804e378..ea41ed576339c878507d68006c942e712999abd5 100644
--- a/db/StoredProcedures.sql
+++ b/db/StoredProcedures.sql
@@ -1089,36 +1089,72 @@ BEGIN
 END //
 
 
+# TODO: split into 2 procedures: get students, get rates
 DROP PROCEDURE IF EXISTS GetRatesForGroupByStage//
-CREATE PROCEDURE `GetRatesForGroupByStage`
-  ( IN `pDisciplineID` INT, IN `pGroupID` INT, IN `pMilestone` INT)
-NO SQL
+CREATE PROCEDURE `GetRatesForGroupByStage` (
+    IN `pDisciplineID` INT,
+    IN `pGroupID` INT,
+    IN `pMilestone` INT
+) NO SQL
 BEGIN
-    SELECT  view_disciplines_students.StudentID,
-        view_disciplines_students.LastName As 'LastName',
-        view_disciplines_students.FirstName As 'FirstName',
-        view_disciplines_students.SecondName As 'SecondName',
-        SUM(rating_table.Rate*(view_roadmap.ModuleType = 'regular')) AS 'Semester',
-        SUM(rating_table.Rate*(view_roadmap.ModuleType = 'bonus')) AS 'Bonus',
-        SUM(rating_table.Rate*(view_roadmap.ModuleType = 'extra')) AS 'Extra',
-        SUM(rating_table.Rate*(view_roadmap.ModuleType = 'exam')*(view_roadmap.SubmoduleOrderNum = pMilestone)) AS 'Exam',
-        MAX(rating_table.Rate*(view_roadmap.ModuleType = 'exam')*(view_roadmap.SubmoduleOrderNum < pMilestone)) AS 'PreviousExam',
-        MAX(IF(view_roadmap.SubmoduleOrderNum = pMilestone, exam_period_options.TYPE, NULL)) As 'Option',
-        MAX(IF(exam_period_options.TYPE = 'pass', 1, 0)) As 'AutoPassed'
-    FROM `view_disciplines_students`
-        LEFT JOIN `view_roadmap` ON view_roadmap.DisciplineID = view_disciplines_students.DisciplineID
-        LEFT JOIN `rating_table` ON rating_table.StudentID = view_disciplines_students.StudentID AND
-                              rating_table.SubmoduleID = view_roadmap.SubmoduleID
-        LEFT JOIN `exam_period_options` ON exam_period_options.submoduleID = view_roadmap.SubmoduleID AND
-                                     exam_period_options.StudentID = view_disciplines_students.StudentID
-    WHERE   view_disciplines_students.DisciplineID = pDisciplineID AND
-        view_disciplines_students.GroupID = pGroupID AND
-        NOT view_disciplines_students.AttachType <=> 'detach' AND
-        (   view_roadmap.ModuleType <> 'extra'  OR
-            (view_roadmap.ModuleType = 'extra' AND view_roadmap.SubmoduleOrderNum < pMilestone )
-        )
-    GROUP BY view_disciplines_students.StudentID
-    ORDER BY LastName ASC, FirstName ASC, SecondName ASC;
+    DECLARE vSemesterID, vGroupID INT DEFAULT -1;
+    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;
+    SELECT disciplines_groups.GroupID INTO vGroupID
+        FROM `disciplines_groups`
+        WHERE   disciplines_groups.GroupID = pGroupID AND
+                disciplines_groups.DisciplineID = pDisciplineID
+        LIMIT 1;
+
+    # get all students from group, that take this discipline
+    IF vGroupID <= 0 THEN # doesn't attached
+        INSERT INTO tStudents (`StudentID`)
+        SELECT disciplines_students.StudentID
+            FROM `disciplines_students`
+            WHERE   disciplines_students.DisciplineID = pDisciplineID AND
+                    disciplines_students.Type = 'attach';
+    ELSE # attached group
+        INSERT INTO tStudents (`StudentID`)
+        SELECT students_groups.StudentID
+            FROM `students_groups`
+            LEFT JOIN `disciplines_students` ON disciplines_students.StudentID = students_groups.StudentID AND
+                                                disciplines_students.DisciplineID = pDisciplineID
+            WHERE   students_groups.GroupID = vGroupID AND
+                    students_groups.SemesterID = vSemesterID AND
+                    NOT disciplines_students.Type <=> 'detach'; # exclude detached students
+    END IF;
+
+    SELECT  tRes.*,
+            students.LastName,
+            students.FirstName,
+            students.SecondName
+        FROM (
+            SELECT  tStudents.StudentID,
+                    SUM(tRate.Rate*(tMap.ModuleType = 'regular')) AS 'Semester',
+                    SUM(tRate.Rate*(tMap.ModuleType = 'bonus')) AS 'Bonus',
+                    SUM(tRate.Rate*(tMap.ModuleType = 'extra')*(tMap.SubmoduleOrderNum < pMilestone)) AS 'Extra',
+                    SUM(tRate.Rate*(tMap.ModuleType = 'extra')*(tMap.SubmoduleOrderNum < pMilestone - 1)) AS 'PreviousExtra',
+                    SUM(tRate.Rate*(tMap.ModuleType = 'exam')*(tMap.SubmoduleOrderNum = pMilestone)) AS 'Exam',
+                    MAX(tRate.Rate*(tMap.ModuleType = 'exam')*(tMap.SubmoduleOrderNum < pMilestone)) AS 'PreviousExam',
+                    MAX(IF(tMap.SubmoduleOrderNum = pMilestone, exam_period_options.TYPE, NULL)) As 'Option',
+                    MAX(IF(exam_period_options.TYPE = 'pass', 1, 0)) As 'AutoPassed'
+                FROM `tStudents`
+                LEFT JOIN `view_roadmap` AS tMap   ON  tMap.DisciplineID = pDisciplineID
+                LEFT JOIN `rating_table` AS tRate  ON  tRate.StudentID = tStudents.StudentID AND
+                                                    tRate.SubmoduleID = tMap.SubmoduleID
+                LEFT JOIN `exam_period_options` ON  exam_period_options.submoduleID = tMap.SubmoduleID AND
+                                                    exam_period_options.StudentID = tStudents.StudentID
+                GROUP BY    tStudents.StudentID
+            ) tRes
+        INNER JOIN `students` ON students.ID = tRes.StudentID
+        ORDER BY    students.LastName ASC,
+                    students.FirstName ASC,
+                    students.SecondName ASC;
 END //