From 5188d5343ee24685a8057590fcb044525006c924 Mon Sep 17 00:00:00 2001
From: Anton Bagliy <taccessviolation@gmail.com>
Date: Wed, 18 Dec 2019 18:48:16 +0300
Subject: [PATCH] FIX: don't select students with leave in global form #551

---
 db/postgresql/issue551_global_form_leave.sql | 56 ++++++++++++++++++++
 1 file changed, 56 insertions(+)
 create mode 100644 db/postgresql/issue551_global_form_leave.sql

diff --git a/db/postgresql/issue551_global_form_leave.sql b/db/postgresql/issue551_global_form_leave.sql
new file mode 100644
index 000000000..30b49c8b7
--- /dev/null
+++ b/db/postgresql/issue551_global_form_leave.sql
@@ -0,0 +1,56 @@
+DROP FUNCTION IF EXISTS public.getratesforstudentsbystage(pdisciplineid integer, pmilestone integer);
+CREATE OR REPLACE FUNCTION public.getratesforstudentsbystage(pdisciplineid integer, pmilestone integer)
+    RETURNS TABLE("StudentID" integer, "Semester" integer, "Bonus" integer, "Extra" integer, "PreviousExtra" integer, "Exam" integer, "PreviousExam" integer, "Option" absence_pass, "AutoPassed" integer, "LastName" character varying, "FirstName" character varying, "SecondName" character varying)
+    LANGUAGE plpgsql
+AS $function$
+
+DECLARE vSemesterID INT DEFAULT -1;
+        vInGeneralGroup BOOL DEFAULT FALSE;
+BEGIN
+    vSemesterID := GetDisciplineProperty(pDisciplineID, 'semester');
+
+    DROP TABLE IF EXISTS tStudents;
+    CREATE TEMPORARY TABLE tStudents AS (
+        SELECT record_books.ID, record_books.StudentID
+        FROM record_books
+                 LEFT JOIN disciplines_students on disciplines_students.DisciplineID = pDisciplineid and
+                                                  disciplines_students.RecordBookID = record_books.ID
+                 JOIN students_groups on record_books.id = students_groups.recordbookid
+                 left join view_disciplines_recordbooks on disciplines_students.recordbookid = view_disciplines_recordbooks.recordbookid
+        WHERE   students_groups.SemesterID = vSemesterID AND
+                students_groups.State <= 'outlet' AND
+                COALESCE(disciplines_students.Type, 'attach') = 'attach' and
+                view_disciplines_recordbooks.disciplineid = pDisciplineid
+    );
+
+    return query
+        SELECT  tRes.*,
+                accounts.LastName as "LastName",
+                accounts.FirstName as "FirstName",
+                accounts.SecondName as "SecondName"
+        FROM (
+                 SELECT  tStudents.StudentID as "StudentID",
+                         cast (SUM(tRate.Rate*iif_sql(tMap.ModuleType = 'regular',1,0)) as integer) AS "Semester",
+                         cast (SUM(tRate.Rate*iif_sql(tMap.ModuleType = 'bonus',1,0)) as integer) AS "Bonus",
+                         cast (SUM(tRate.Rate*iif_sql(tMap.ModuleType = 'extra',1,0)*iif_sql(tMap.SubmoduleOrderNum < pMilestone,1,0)) as integer) AS "Extra",
+                         cast (SUM(tRate.Rate*iif_sql(tMap.ModuleType = 'extra',1,0)*iif_sql(tMap.SubmoduleOrderNum < pMilestone - 1,1,0)) as integer) AS "PreviousExtra",
+                         cast (SUM(tRate.Rate*iif_sql(tMap.ModuleType = 'exam',1,0)*iif_sql(tMap.SubmoduleOrderNum = pMilestone,1,0)) as integer) AS "Exam",
+                         MAX(tRate.Rate*iif_sql(tMap.ModuleType = 'exam',1,0)*iif_sql(tMap.SubmoduleOrderNum < pMilestone,1,0)) AS "PreviousExam",
+                         MAX(CASE WHEN tMap.SubmoduleOrderNum = pMilestone THEN  exam_period_options."type" ELSE  NULL END) As "Option",
+                         MAX(CASE WHEN exam_period_options."type" = 'pass' THEN  1 ELSE  0 END) As "AutoPassed"
+                 FROM tStudents
+                          LEFT JOIN view_roadmap AS tMap   ON  tMap.DisciplineID = pDisciplineID
+                          LEFT JOIN rating_table AS tRate  ON  tRate.RecordbookID = tStudents.ID AND
+                                                               tRate.SubmoduleID = tMap.SubmoduleID
+                          LEFT JOIN exam_period_options ON  exam_period_options.submoduleID = tMap.SubmoduleID AND
+                                                            exam_period_options.RecordbookID = tStudents.ID
+                 GROUP BY tStudents.StudentID
+             ) tRes
+                 INNER JOIN students ON students.ID = tRes."StudentID"
+                 INNER JOIN accounts ON students.AccountID = accounts.ID
+        ORDER BY    accounts.LastName ASC,
+                    accounts.FirstName ASC,
+                    accounts.SecondName ASC;
+END
+$function$;
+
-- 
GitLab