From 888046f12070f34024030b96f07f39c7897296e0 Mon Sep 17 00:00:00 2001 From: Roman Steinberg <roman.accs@gmail.com> Date: Sun, 26 Aug 2018 20:59:34 +0300 Subject: [PATCH] ADD: getFullInfo function (#286) --- db/postgresql/functions.sql | 152 ++++++++++++++++++++++++++++++++++++ 1 file changed, 152 insertions(+) diff --git a/db/postgresql/functions.sql b/db/postgresql/functions.sql index 75e4e22b0..80e59edae 100644 --- a/db/postgresql/functions.sql +++ b/db/postgresql/functions.sql @@ -4025,6 +4025,157 @@ begin END $$ LANGUAGE plpgsql; +-- +-- Name: getfullinfo(integer,integer); Type: FUNCTION; Schema: public; Owner: - +-- +DROP FUNCTION IF EXISTS public.getfullinfo(integer,integer); + +CREATE OR REPLACE FUNCTION public.getfullinfo(puserid integer, psemesterid integer) + RETURNS table ( + "StudentID" integer, + "GroupID" integer, + "GroupNum" integer, + "GroupName" varchar, + "GradeID" integer, + "GradeNum" integer, + "Degree" bachelor_master_specialist, + "SpecID" integer, + "SpecName" varchar, + "SpecAbbr" varchar, + "SpecCode" varchar, + "SemesterID" integer, + -- teacher info + "TeacherID" integer, + "DepID" integer, + "DepName" varchar, + "JobPositionName" varchar, + --faculty info + "FacultyID" integer, + "FacultyName" varchar, + "FacultyAbbr" varchar, + -- account info + "ID" integer, + "Login" varchar, + "EMail" varchar, + "LastName" varchar, + "FirstName" varchar, + "SecondName" varchar, + "Type" student_teacher, + "RoleID" integer, + "Role" varchar, + "RoleMark" integer, + "IsEnabled" int2, + "Code" varchar + ) +AS $$ +DECLARE vAccountType student_teacher; +begin + + 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 + return query + SELECT + -- personal students info + students.ID as "StudentID", + -- group info + view_groups_reduced.groupid as "GroupID", + view_groups_reduced.groupnum as "GroupNum", + view_groups_reduced.groupname as "GroupName", + view_groups_reduced.gradeid as "GradeID", + view_groups_reduced.gradenum as "GradeNum", + view_groups_reduced."degree" as "Degree", + view_groups_reduced.specid as "SpecID", + view_groups_reduced.specname as "SpecName", + view_groups_reduced.specabbr as "SpecAbbr", + view_groups_reduced.speccode as "SpecCode", + students_groups.SemesterID as "SemesterID", + -- teacher info + cast(null as integer) as "TeacherID", + cast(null as integer) as "DepID", + cast(null as varchar) as "DepName", + cast(null as varchar) as "JobPositionName", + + --faculty info + view_groups_reduced.facultyid as "FacultyID", + view_groups_reduced.facultyname as "FacultyName", + view_groups_reduced.facultyabbr as "FacultyAbbr", + -- account info + accounts.ID as "ID", + accounts.Login as "Login", + accounts.EMail as "EMail", + accounts.LastName as "LastName", + accounts.FirstName as "FirstName", + accounts.SecondName as "SecondName", + user_roles."type" as "Type", + accounts.UserRoleID AS "RoleID", + user_roles.RoleName AS "Role", + user_roles.Mark AS "RoleMark", + accounts.IsEnabled as "IsEnabled", + accounts.ActivationCode AS "Code" + FROM students + INNER JOIN accounts ON accounts.ID = students.AccountID + INNER JOIN user_roles ON user_roles.ID = accounts.UserRoleID + LEFT JOIN record_books ON record_books.StudentID = students.ID + LEFT JOIN students_groups ON students_groups.RecordBookID = record_books.ID + LEFT JOIN view_groups_reduced ON view_groups_reduced.GroupID = students_groups.GroupID + WHERE students.AccountID = pUserID and (pSemesterID is null or students_groups.SemesterID = pSemesterID ) + ORDER BY students_groups.SemesterID DESC + LIMIT 1; + ELSE + return query + SELECT + -- personal students info не олучается поставить null???? + cast(null as integer) as "StudentID", + -- group info + cast(null as integer) as "GroupID", + cast(null as integer) as "GroupNum", + cast(null as varchar) as "GroupName", + cast(null as integer) as "GradeID", + cast(null as integer) as "GradeNum", + cast(null as bachelor_master_specialist) as "Degree", + cast(null as integer) as "SpecID", + cast(null as varchar) as "SpecName", + cast(null as varchar) as "SpecAbbr", + cast(null as varchar) as "SpecCode", + cast(null as integer) as "SemesterID", + -- teacher info + view_teachers.TeacherID as "TeacherID", + view_teachers.DepID as "DepID", + view_teachers.DepName as "DepName", + view_teachers.JobPositionName as "JobPositionName", + --faculty info + view_teachers.FacultyID as "FacultyID", + view_teachers.FacultyName as "FacultyName", + view_teachers.FacultyAbbr as "FacultyAbbr", + + -- account info + accounts.ID as "ID", + accounts.Login as "Login", + accounts.EMail as "EMail", + accounts.LastName as "LastName", + accounts.FirstName as "FirstName", + accounts.SecondName as "SecondName", + user_roles."type" as "Type", + accounts.UserRoleID AS "RoleID", + user_roles.RoleName AS "Role", + user_roles.Mark AS "RoleMark", + accounts.IsEnabled as "IsEnabled", + accounts.ActivationCode AS "Code" + 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 +$$ LANGUAGE plpgsql; --- Триггеры ---------------------------------------------------------------------------------------------------------------------------- @@ -4183,3 +4334,4 @@ end CREATE trigger tr_d_submodule before delete on submodules for each row execute procedure submodule_d(); + -- GitLab