From f4e8fc825fbd4d4f43228d835ca0823c1179ee37 Mon Sep 17 00:00:00 2001 From: Roman Steinberg <roman.accs@gmail.com> Date: Sat, 1 Sep 2018 20:35:13 +0300 Subject: [PATCH] convert functions Plan_GetTeachers, GetRatesHistory, DeleteModuleExam, GetStudents, SearchStudents (#286) --- db/postgresql/functions.sql | 225 ++++++++++++++++++++++++++++++++++++ 1 file changed, 225 insertions(+) diff --git a/db/postgresql/functions.sql b/db/postgresql/functions.sql index 93864b183..a46ac5398 100644 --- a/db/postgresql/functions.sql +++ b/db/postgresql/functions.sql @@ -4179,6 +4179,231 @@ begin END $$ LANGUAGE plpgsql; +-- +-- Name: Plan_GetTeachers(integer,integer,integer); Type: FUNCTION; Schema: public; Owner: - +-- +DROP FUNCTION IF EXISTS public."Plan_GetTeachers"(INTEGER, INTEGER, INTEGER); + +CREATE OR REPLACE FUNCTION public."Plan_GetTeachers"(pStudyPlanID INTEGER, pSemesterID INTEGER, + pLoadAll INTEGER) -- todo: replace bool + RETURNS TABLE( + "ID" integer + ) +AS $$ +--select * from public.getgroups( +-- :pgradeid, -- put the pgradeid parameter value instead of 'pgradeid' (int4) +-- :pfacultyid, -- put the pfacultyid parameter value instead of 'pfacultyid' (int4) +-- :psemesterid -- put the psemesterid parameter value instead of 'psemesterid' (int4) +--); +SELECT teachers.ID AS "ID" +FROM teachers + INNER JOIN disciplines_teachers ON disciplines_teachers.TeacherID = teachers.ID + INNER JOIN disciplines ON disciplines.ID = disciplines_teachers.DisciplineID + INNER JOIN disciplines_study_plans ON disciplines_study_plans.DisciplineID = disciplines.ID +WHERE disciplines_study_plans.StudyPlanID = pStudyPlanID AND + disciplines.SemesterID = COALESCE(pSemesterID, disciplines.SemesterID) AND + (pLoadAll = 1 OR disciplines.Subtype IS NULL); +$$ LANGUAGE sql; + +-- +-- Name: GetRatesHistory(integer); Type: FUNCTION; Schema: public; Owner: - +-- +DROP FUNCTION IF EXISTS public."GetRatesHistory"(INTEGER); + +CREATE OR REPLACE FUNCTION public."GetRatesHistory"( + pDisciplineID INTEGER) + RETURNS TABLE( + "ID" INTEGER, + "Date" DATE, + "Rate" INTEGER, + "StudentLast" VARCHAR, + "StudentFirst" VARCHAR, + "StudentSecond" VARCHAR, + "TeacherLast" VARCHAR, + "TeacherFirst" VARCHAR, + "TeacherSecond" VARCHAR, + "SubmoduleName" VARCHAR, + "ModuleName" VARCHAR + ) +AS $$ +SELECT logs_rating.ID AS "ID", + DATE(logs_rating.Date) As "Date", + logs_rating.Rate AS "Rate", + studentAccount.LastName AS "StudentLast", + studentAccount.FirstName AS "StudentFirst", + studentAccount.SecondName AS "StudentSecond", + teacherAccount.LastName AS "TeacherLast", + teacherAccount.FirstName AS "TeacherFirst", + teacherAccount.SecondName AS "TeacherSecond", + submodules.Name AS "SubmoduleName", + modules.Name AS "ModuleName" +FROM logs_rating + INNER JOIN record_books ON record_books.ID = logs_rating.RecordBookID + INNER JOIN students ON students.ID = record_books.StudentID + INNER JOIN accounts as studentAccount ON students.AccountID = studentAccount.ID + INNER JOIN teachers ON teachers.ID = logs_rating.TeacherID + INNER JOIN accounts as teacherAccount ON teachers.AccountID = teacherAccount.ID + INNER JOIN submodules ON submodules.ID = logs_rating.SubmoduleID + INNER JOIN modules ON modules.ID = submodules.ModuleID +WHERE modules.DisciplineID = pDisciplineID +ORDER BY logs_rating.Date DESC; +$$ LANGUAGE sql; + +-- +-- Name: DeleteModuleExam(integer); Type: FUNCTION; Schema: public; Owner: - +-- +DROP FUNCTION IF EXISTS public."DeleteModuleExam"(INTEGER, INTEGER); + +CREATE OR REPLACE FUNCTION public."DeleteModuleExam"( + pTeacherID INTEGER, + pDisciplineID INTEGER) + RETURNS INTEGER +AS $$ +DECLARE vExamModuleID INTEGER DEFAULT -1; +BEGIN + -- check teacher rights + IF NOT InternalIsTeacherAuthor(pTeacherID, pDisciplineID) OR + InternalIsMapLocked(pDisciplineID) + THEN + RETURN -1; + END IF; + + -- get exam module ID + SELECT modules.ID INTO vExamModuleID + FROM modules + WHERE modules.Type = 'exam' AND + modules.DisciplineID = pDisciplineID + LIMIT 1; + + IF vExamModuleID <= 0 THEN + RETURN -1; + END IF; + + -- everything is checked then delete + DELETE FROM submodules + WHERE vExamModuleID = submodules.ModuleID; + + DELETE FROM modules + WHERE vExamModuleID = modules.ID; + RETURN 0; +END +$$ LANGUAGE plpgsql; + + +-- +-- Name: GetStudents(INTEGER, INTEGER, INTEGER, INTEGER, VARCHAR(100), VARCHAR(100), VARCHAR(100)); +-- Type: FUNCTION; Schema: public; Owner: - +-- +DROP FUNCTION IF EXISTS public."GetStudents"(INTEGER, INTEGER, INTEGER, INTEGER, VARCHAR(100), VARCHAR(100), VARCHAR(100)); + +CREATE OR REPLACE FUNCTION public."GetStudents"( + pFacultyID INTEGER, + pGradeID INTEGER, + pGroupID INTEGER, + pSemesterID INTEGER, + pWord1 VARCHAR(100), + pWord2 VARCHAR(100), + pWord3 VARCHAR(100)) + RETURNS TABLE( + "ID" INTEGER, + "LastName" VARCHAR, + "FirstName" VARCHAR, + "SecondName" VARCHAR, + "AccountID" INTEGER, + "GradeID" INTEGER, + "GradeNum" INTEGER, + "Degree" INTEGER, + "GroupID" INTEGER, + "GroupNum" INTEGER + ) +AS $$ +DECLARE FullName VARCHAR; +BEGIN + SELECT view_students.StudentID AS "ID", + view_students.LastName AS "LastName", + view_students.FirstName AS "FirstName", + view_students.SecondName AS "SecondName", + view_students.AccountID AS "AccountID", + view_students.GradeID AS "GradeID", + view_students.GradeNum AS "GradeNum", + view_students.Degree AS "Degree", + view_students.GroupID AS "GroupID", + view_students.GroupNum AS "GroupNum", + CONCAT(view_students.LastName, ' ', view_students.FirstName, ' ', view_students.SecondName) AS "FullName" + FROM view_students + WHERE + CASE WHEN pSemesterID != 0 THEN view_students.SemesterID = pSemesterID ELSE + TRUE + END 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 FullName != '' THEN + FullName LIKE CONCAT('%', pWord1, '%') AND + FullName LIKE CONCAT('%', pWord2, '%') AND + FullName LIKE CONCAT('%', pWord3, '%') + ELSE TRUE END; +END +$$ LANGUAGE plpgsql; + +-- +-- Name: SearchStudents(INTEGER, INTEGER, INTEGER, VARCHAR(100), INTEGER); +-- Type: FUNCTION; Schema: public; Owner: - +-- +DROP FUNCTION IF EXISTS public."SearchStudents"(INTEGER, INTEGER, INTEGER, VARCHAR(100), INTEGER); + +CREATE OR REPLACE FUNCTION public."SearchStudents"( + pGradeID INTEGER, + pGroupID INTEGER, + pFacultyID INTEGER, + pFullName VARCHAR(100), + pDisciplineID INTEGER) + RETURNS TABLE( + "ID" INTEGER, + "LastName" VARCHAR, + "FirstName" VARCHAR, + "SecondName" VARCHAR, + "GradeID" INTEGER, + "GradeNum" INTEGER, + "Degree" INTEGER, + "GroupID" INTEGER, + "GroupNum" INTEGER + ) +AS $$ +DECLARE vSemesterID INTEGER DEFAULT -1; + DECLARE vRes INTEGER DEFAULT -1; +BEGIN + + DROP TABLE IF EXISTS tDisciplineStudents; + SELECT Discipline_GetStudentsTemp(pDisciplineID) INTO vRes; + + SELECT view_students.StudentID AS "ID", + view_students.LastName AS "LastName", + view_students.FirstName AS "FirstName", + view_students.SecondName AS "SecondName", + view_students.GradeID AS "GradeID", + view_students.GradeNum AS "GradeNum", + view_students.Degree AS "Degree", + view_students.GroupID AS "GroupID", + view_students.GroupNum AS "GroupNum", + CONCAT(view_students.LastName, ' ', view_students.FirstName, ' ', view_students.SecondName) AS "FullName" + 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 + FullName LIKE CONCAT('%', pFullName, '%') + ELSE TRUE END + ORDER BY view_students.GradeID ASC, + view_students.GroupID ASC, + view_students.LastName ASC, + view_students.FirstName ASC; +END +$$ LANGUAGE plpgsql; + --- Триггеры ---------------------------------------------------------------------------------------------------------------------------- -- -- GitLab