diff --git a/db/StoredFunctions.sql b/db/StoredFunctions.sql
index 4bd995c0cfc24ff93a843675f6ad679044f70a82..fb737913550b43a60f4a25ac7dfe7a3ffaef8991 100644
--- a/db/StoredFunctions.sql
+++ b/db/StoredFunctions.sql
@@ -34,6 +34,8 @@ DROP FUNCTION IF EXISTS AddDiscipline//
 
 DROP FUNCTION IF EXISTS GetMaxRateForDisc//
 
+DROP FUNCTION IF EXISTS BindTeacher//
+
 
 
 # -------------------------------------------------------------------------------------------
@@ -248,25 +250,38 @@ END //
 # Label: semesters
 # -------------------------------------------------------------------------------------------
 
+DROP FUNCTION IF EXISTS GetDisciplineSemesterID//
+CREATE FUNCTION `GetDisciplineSemesterID` (
+    `pDisciplineID` INT
+) RETURNS int(11)
+    NO SQL
+BEGIN
+    DECLARE vSemesterID INT DEFAULT -1;
+
+    SELECT disciplines.SemesterID INTO vSemesterID
+    FROM `disciplines`
+    WHERE disciplines.ID = pDisciplineID
+    LIMIT 1;
 
+    RETURN vSemesterID;
+END //
 
 # -------------------------------------------------------------------------------------------
 # Label: faculties
 # -------------------------------------------------------------------------------------------
 
-# TODO: return faculty id
 DROP FUNCTION IF EXISTS CreateFaculty //
 CREATE FUNCTION CreateFaculty (
         `pFacultyName` TEXT CHARSET utf8,
         `pFacultyAbbr` TEXT CHARSET utf8
-    ) RETURNS INT(11) # 0 - success
+    ) RETURNS INT(11) # -1 or id
     NO SQL
 BEGIN
     DECLARE EXIT HANDLER FOR SQLEXCEPTION RETURN -1;
 
     INSERT INTO faculties
         (Name, Abbr) VALUES(pFacultyName, pFacultyAbbr);
-    RETURN 0;
+    RETURN LAST_INSERT_ID();
 END//
 
 # -------------------------------------------------------------------------------------------
@@ -369,6 +384,25 @@ BEGIN
 END //
 
 
+DROP FUNCTION IF EXISTS GetStudentGroup//
+CREATE FUNCTION `GetStudentGroup` (
+    `pStudentID` INT,
+    `pSemesterID` INT
+) RETURNS int(11) # groupID or -1 if failed
+    NO SQL
+BEGIN
+    DECLARE vGroupID INT DEFAULT -1;
+
+    SELECT students_groups.GroupID INTO vGroupID
+        FROM `students_groups`
+        WHERE   students_groups.StudentID = pStudentID AND
+                students_groups.SemesterID = pSemesterID
+        LIMIT 1;
+
+    RETURN vGroupID;
+END //
+
+
 
 
 # -------------------------------------------------------------------------------------------
@@ -663,6 +697,7 @@ BEGIN
         INNER JOIN `accounts` ON teachers.AccountID=accounts.ID
         WHERE teachers.ID = pTeacherID
         LIMIT 1;
+    # TODO: magic constants
     IF vUserRole = 4 THEN # 4 - сотрудник деканата
         RETURN 0;
     END IF;
@@ -677,7 +712,6 @@ END //
 # -------------------------------------------------------------------------------------------
 
 # TODO: magic constants (UserRoleID)
-# TODO: transaction
 # TODO: group id instead num and grade
 DROP FUNCTION IF EXISTS CreateStudent//
 CREATE FUNCTION `CreateStudent` (
@@ -796,24 +830,6 @@ END //
 # -------------------------------------------------------------------------------------------
 
 
-
-DROP FUNCTION IF EXISTS GetDisciplineSemesterID//
-CREATE FUNCTION `GetDisciplineSemesterID` (
-    `pDisciplineID` INT
-) RETURNS int(11)
-    NO SQL
-BEGIN
-    DECLARE vSemesterID INT DEFAULT -1;
-
-    SELECT disciplines.SemesterID INTO vSemesterID
-        FROM `disciplines`
-        WHERE disciplines.ID = pDisciplineID
-        LIMIT 1;
-
-    RETURN vSemesterID;
-END //
-
-
 DROP FUNCTION IF EXISTS Discipline_Create//
 CREATE FUNCTION `Discipline_Create` (
     `pTeacherID` INT,
@@ -968,10 +984,10 @@ BEGIN
 
     # get exam type and extra module ID
     SELECT disciplines.ExamType, modules.ID INTO vOldExamType, vExtraID
-        FROM `disciplines`
-        INNER JOIN `modules` ON  modules.DisciplineID = pDisciplineID AND
-                                 modules.Type = 'extra'
-        WHERE disciplines.ID = pDisciplineID
+        FROM `modules`
+        INNER JOIN `disciplines` ON disciplines.ID = modules.DisciplineID
+        WHERE   modules.DisciplineID = pDisciplineID AND
+                modules.Type = 'extra'
         LIMIT 1;
     IF vExtraID <= 0 THEN
         RETURN -1;
@@ -1064,8 +1080,10 @@ CREATE FUNCTION `BindGroup` (
     ) RETURNS int(11)
     NO SQL
 BEGIN
-    DECLARE vChecker, vSemesterID INT DEFAULT -1;
+    DECLARE vSemesterID INT DEFAULT -1;
     DECLARE EXIT HANDLER FOR SQLEXCEPTION RETURN -3;
+    SET @isAttached := -1;
+
 
     # 1. check if AccessedTeacher is author
     IF  NOT InternalIsTeacherAuthor(pTeacherID, pDisciplineID) OR
@@ -1074,36 +1092,27 @@ BEGIN
         RETURN -1;
     END IF;
 
-    # 2. check if group is bound to discipline
-    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;
-
-    # TODO: add param SemesterID
-    SELECT disciplines.SemesterID INTO vSemesterID
-        FROM `disciplines`
-        WHERE disciplines.ID = pDisciplineID
-        LIMIT 1;
-
-    # 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_groups.StudentID
-                        FROM `students_groups`
-                        WHERE   students_groups.GroupID = pGroupID AND
-                                students_groups.SemesterID = vSemesterID
-                );
-
-    # 4. bind whole group
+    # 2. bind whole group
     INSERT INTO `disciplines_groups`
         (DisciplineID, GroupID)
-        VALUES (pDisciplineID, pGroupID );
+        VALUES ( pDisciplineID, pGroupID )
+        ON DUPLICATE KEY UPDATE
+            disciplines_groups.ID = ( @isAttached := LAST_INSERT_ID(disciplines_groups.ID) );
+
+    IF @isAttached < 0 THEN # group was attached
+        SET vSemesterID = GetDisciplineSemesterID(pDisciplineID);
+
+        # 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_groups.StudentID
+                            FROM `students_groups`
+                            WHERE   students_groups.GroupID = pGroupID AND
+                                    students_groups.SemesterID = vSemesterID
+                        );
+    END IF;
+
     RETURN 0;
 END //
 
@@ -1117,26 +1126,23 @@ CREATE FUNCTION `BindStudent` (
     )   RETURNS int(11)
     NO SQL
 BEGIN
-    DECLARE vChecker, vGroupID, vTemp, vSemesterID INT DEFAULT -1;
+    DECLARE vChecker, vStudentGroupID, vTemp, vSemesterID INT DEFAULT -1;
     DECLARE vInGroup BOOLEAN DEFAULT FALSE;
     DECLARE EXIT HANDLER FOR SQLEXCEPTION RETURN -1;
 
-    SET vSemesterID = GetDisciplineSemesterID(pDisciplineID);
-
     # 1. check if AccessedTeacher is author
     IF NOT InternalIsTeacherAuthor(pTeacherID, pDisciplineID) THEN
         RETURN -1;
     END IF;
 
-    # TODO: extract method - Get Student Group
+    SET vSemesterID = GetDisciplineSemesterID(pDisciplineID);
+    SET vStudentGroupID = GetStudentGroup(pStudentID, vSemesterID);
+
     # 2. check if student's group is bound yet
     SET vInGroup = EXISTS(
-        SELECT disciplines_groups.ID
-            FROM `students_groups`
-            INNER JOIN `disciplines_groups` ON disciplines_groups.DisciplineID = pDisciplineID AND
-                                               disciplines_groups.GroupID = students_groups.GroupID
-            WHERE students_groups.StudentID = pStudentID AND
-                  students_groups.SemesterID = vSemesterID
+        SELECT * FROM `disciplines_groups`
+            WHERE disciplines_groups.DisciplineID = pDisciplineID AND
+                  disciplines_groups.GroupID = vStudentGroupID
             LIMIT 1
     );
 
@@ -1169,7 +1175,7 @@ CREATE FUNCTION `UnbindGroup` (
 BEGIN
     DECLARE vSemesterID INT DEFAULT -1;
 
-    IF NOT InternalIsTeacherAuthor(pTeacherID, pDisciplineID) OR InternalIsMapLocked(pDisciplineID)THEN
+    IF NOT InternalIsTeacherAuthor(pTeacherID, pDisciplineID) OR InternalIsMapLocked(pDisciplineID) THEN
         RETURN -1;
     END IF;
 
@@ -1179,11 +1185,7 @@ BEGIN
                 disciplines_groups.GroupID = pGroupID
         LIMIT 1;
 
-    # TODO: add param SemesterID
-    SELECT disciplines.SemesterID INTO vSemesterID
-        FROM `disciplines`
-        WHERE disciplines.ID = pDisciplineID
-        LIMIT 1;
+    SET vSemesterID = GetDisciplineSemesterID(pDisciplineID);
 
     # delete attached, and detached (doesn't take disc in any case)
     DELETE FROM `disciplines_students`
@@ -1207,26 +1209,23 @@ CREATE FUNCTION `UnbindStudent` (
     ) RETURNS int(11)
     NO SQL
 BEGIN
-    DECLARE vInGroup, vSemesterID INT DEFAULT -1;
+    DECLARE vInGroup, vStudentGroupID, vSemesterID INT DEFAULT -1;
     DECLARE EXIT HANDLER FOR SQLEXCEPTION RETURN -1;
+
     IF  NOT InternalIsTeacherAuthor(pTeacherID, pDisciplineID) THEN
         RETURN -1;
     END IF;
 
     SET vSemesterID = GetDisciplineSemesterID(pDisciplineID);
+    SET vStudentGroupID = GetStudentGroup(pStudentID, vSemesterID);
 
-    # TODO: extract method - GetDisciplineSemesterID
-    # TODO: join students_groups by discipline SemesterID
-
-    # try to get general group, if student in it.
-    SELECT disciplines_groups.ID INTO vInGroup
-        FROM `students`
-        INNER JOIN `students_groups` ON students_groups.StudentID = students.ID AND
-                                        students_groups.SemesterID = vSemesterID
-        INNER JOIN `disciplines_groups` ON disciplines_groups.DisciplineID = pDisciplineID AND
-                                           disciplines_groups.GroupID = students_groups.GroupID
-        WHERE students.ID = pStudentID
-        LIMIT 1;
+    # 2. check if student's group is bound yet
+    SET vInGroup = EXISTS(
+        SELECT * FROM `disciplines_groups`
+        WHERE disciplines_groups.DisciplineID = pDisciplineID AND
+              disciplines_groups.GroupID = vStudentGroupID
+        LIMIT 1
+    );
 
     IF vInGroup > 0 THEN # student in general group
         INSERT INTO `disciplines_students`
@@ -1234,16 +1233,15 @@ BEGIN
             VALUES (pDisciplineID, pStudentID, 'detach');
     ELSE
         DELETE FROM `disciplines_students`
-        WHERE disciplines_students.DisciplineID = pDisciplineID AND
-            disciplines_students.StudentID = pStudentID
-        LIMIT 1;
+            WHERE   disciplines_students.DisciplineID = pDisciplineID AND
+                    disciplines_students.StudentID = pStudentID
+            LIMIT 1;
     END IF;
     RETURN 0;
 END //
 
 
 
-DROP FUNCTION IF EXISTS BindTeacher//
 DROP FUNCTION IF EXISTS Discipline_BindTeacher//
 CREATE FUNCTION `Discipline_BindTeacher` (
     `pDisciplineID` INT,
@@ -1252,7 +1250,7 @@ CREATE FUNCTION `Discipline_BindTeacher` (
     NO SQL
 BEGIN
     DECLARE EXIT HANDLER FOR SQLEXCEPTION RETURN -1;
-  
+
     # try to insert BindingTeacher in access list
     INSERT INTO `disciplines_teachers`
         (DisciplineID, TeacherID)
@@ -1274,7 +1272,8 @@ CREATE FUNCTION `Discipline_UnbindTeacher` (
 BEGIN
     DELETE FROM `disciplines_teachers`
         WHERE   disciplines_teachers.DisciplineID = pDisciplineID AND
-                disciplines_teachers.TeacherID = pBindingTeacher;
+                disciplines_teachers.TeacherID = pBindingTeacher
+        LIMIT 1;
     RETURN ROW_COUNT()-1;
 END //
 
@@ -1382,13 +1381,10 @@ CREATE FUNCTION `Discipline_CountRatings` (
 BEGIN
     DECLARE vRes INT DEFAULT 0;
 
-    SELECT COUNT(rating_table.StudentID)
-        INTO vRes
-        FROM `rating_table`
-        INNER JOIN `submodules` ON rating_table.SubmoduleID = submodules.ID
-        INNER JOIN `modules` ON submodules.ModuleID = modules.ID
-        WHERE modules.DisciplineID = pDisciplineID
-        LIMIT 1;
+    SELECT COUNT(rating_table.StudentID) INTO vRes
+        FROM `view_roadmap`
+        LEFT JOIN `rating_table` ON rating_table.SubmoduleID = view_roadmap.SubmoduleID
+        WHERE view_roadmap.DisciplineID = pDisciplineID;
 
     RETURN vRes;
 END //
@@ -1430,13 +1426,13 @@ BEGIN
     RETURN 0;
 END //
 
+
+
 # -------------------------------------------------------------------------------------------
 # Label: modules
 # Label: roadmap
 # -------------------------------------------------------------------------------------------
 
-
-
 DROP FUNCTION IF EXISTS ChangeModuleName//
 CREATE FUNCTION `ChangeModuleName` (
         `pTeacherID` INT,
@@ -1478,7 +1474,7 @@ BEGIN
         FROM `modules`
         WHERE   modules.DisciplineID = pDisciplineID AND modules.Type = 'regular'
         LIMIT 1;
-    IF vOrderNum IS NULL THEN
+    IF vOrderNum IS NULL THEN # TODO: check unreachable code
         SET vOrderNum = 1;
     END IF;
 
@@ -1497,21 +1493,21 @@ CREATE FUNCTION `AddModuleExam` (
     ) RETURNS int(11)
     NO SQL
 BEGIN
-    DECLARE vChecker, vModule INT DEFAULT -1;
+    DECLARE vModule, vChecker INT DEFAULT -1;
+    DECLARE vIsExamExists BOOLEAN;
     IF  NOT InternalIsTeacherAuthor(pTeacherID, pDisciplineID) OR
         InternalIsMapLocked(pDisciplineID)
     THEN
         RETURN -1;
     END IF;
 
-    # TODO: exists
-    # check exam module existence
-    SELECT modules.ID
-        INTO vChecker
-        FROM `modules`
-        WHERE   modules.DisciplineID = pDisciplineID AND
-                modules.Type = 'exam';
-    IF vChecker > 0 THEN
+    SET vIsExamExists = EXISTS(
+        SELECT * FROM `modules`
+            WHERE   modules.DisciplineID = pDisciplineID AND
+                    modules.Type = 'exam'
+            LIMIT 1
+    );
+    IF vIsExamExists THEN
         RETURN -2;
     END IF;
 
@@ -1558,8 +1554,7 @@ BEGIN
 
 
     # get discipline exam type
-    SELECT  modules.ID, disciplines.ExamType
-        INTO vModule, vType
+    SELECT  modules.ID, disciplines.ExamType INTO vModule, vType
         FROM `modules`
         INNER JOIN `disciplines` ON disciplines.ID = modules.DisciplineID
         WHERE   modules.DisciplineID = pDisciplineID AND