Skip to content

Commit

Permalink
feat: modified student lesson summaries to include enrollments, updat…
Browse files Browse the repository at this point in the history
…ed trigger
  • Loading branch information
KralMarko123 committed Jul 22, 2024
1 parent 738491a commit 7dcb52f
Show file tree
Hide file tree
Showing 3 changed files with 144 additions and 13 deletions.
Original file line number Diff line number Diff line change
@@ -0,0 +1,82 @@
class UpdateStudentLessonSummariesWithEnrollments < ActiveRecord::Migration[7.1]
def up
drop_view :group_lesson_summaries
drop_view :lesson_table_rows

update_view :student_lesson_summaries, version: 7

create_view :group_lesson_summaries, version: 4
create_view :lesson_table_rows, version: 3
update_trigger
end

def down
drop_view :group_lesson_summaries
drop_view :lesson_table_rows

update_view :student_lesson_summaries, version: 6

create_view :group_lesson_summaries, version: 4
create_view :lesson_table_rows, version: 3
old_trigger
end

def update_trigger
execute <<~SQL
create or replace function update_enrollments()
returns trigger AS
$BODY$
declare
current_enrollment_group_id int := null;
BEGIN
SELECT group_id into current_enrollment_group_id FROM enrollments e where e.student_id = new.id and e.inactive_since is null;
if current_enrollment_group_id is null then
insert into enrollments (student_id, group_id, active_since, inactive_since, created_at, updated_at)
values (new.id, new.group_id, now(), null, now(), now());
else if current_enrollment_group_id != new.group_id then
if (SELECT group_id from enrollments e where e.student_id = new.id and e.group_id = new.group_id) is null then
insert into enrollments (student_id, group_id, active_since, inactive_since, created_at, updated_at)
values (new.id, new.group_id, now(), null, now(), now());
else
update enrollments set inactive_since = null, active_since = now(), updated_at = now()
where group_id = new.group_id and student_id = new.id;
end if;
update enrollments set inactive_since = now(), updated_at = now()
where inactive_since is null and group_id = current_enrollment_group_id and student_id = new.id;
end if;
end if;
return new;
END;
$BODY$ language plpgsql;
drop trigger if exists update_enrollments_on_student_group_change_trigger on students;
create trigger update_enrollments_on_student_group_change_trigger
after insert or update on students for each row execute procedure update_enrollments();
SQL
end

def old_trigger
execute <<~SQL
create or replace function update_enrollments()
returns trigger AS
$BODY$
declare
current_enrollment_group_id int := null;
BEGIN
SELECT group_id into current_enrollment_group_id FROM enrollments e where e.student_id = new.id;
if current_enrollment_group_id is null or current_enrollment_group_id != new.group_id then
update enrollments set inactive_since = now() where inactive_since is null;
insert into enrollments (student_id, group_id, active_since, inactive_since, created_at, updated_at)
values (new.id, new.group_id, now(), null, now(), now());
end if;
return new;
END;
$BODY$ language plpgsql;
drop trigger if exists update_enrollments_on_student_group_change_trigger on students;
create trigger update_enrollments_on_student_group_change_trigger
after insert or update on students for each row execute procedure update_enrollments();
SQL
end
end
39 changes: 26 additions & 13 deletions db/structure.sql
Original file line number Diff line number Diff line change
Expand Up @@ -72,11 +72,22 @@ CREATE FUNCTION public.update_enrollments() RETURNS trigger
declare
current_enrollment_group_id int := null;
BEGIN
SELECT group_id into current_enrollment_group_id FROM enrollments e where e.student_id = new.id;
if current_enrollment_group_id is null or current_enrollment_group_id != new.group_id then
update enrollments set inactive_since = now() where inactive_since is null;
insert into enrollments (student_id, group_id, active_since, inactive_since, created_at, updated_at)
values (new.id, new.group_id, now(), null, now(), now());
SELECT group_id into current_enrollment_group_id FROM enrollments e where e.student_id = new.id and e.inactive_since is null;
if current_enrollment_group_id is null then
insert into enrollments (student_id, group_id, active_since, inactive_since, created_at, updated_at)
values (new.id, new.group_id, now(), null, now(), now());
else if current_enrollment_group_id != new.group_id then
if (SELECT group_id from enrollments e where e.student_id = new.id and e.group_id = new.group_id) is null then
insert into enrollments (student_id, group_id, active_since, inactive_since, created_at, updated_at)
values (new.id, new.group_id, now(), null, now(), now());
else
update enrollments set inactive_since = null, active_since = now(), updated_at = now()
where group_id = new.group_id and student_id = new.id;
end if;

update enrollments set inactive_since = now(), updated_at = now()
where inactive_since is null and group_id = current_enrollment_group_id and student_id = new.id;
end if;
end if;
return new;
END;
Expand Down Expand Up @@ -1708,10 +1719,12 @@ CREATE OR REPLACE VIEW public.student_lesson_summaries AS
l.subject_id,
round(avg(grades.mark), 2) AS average_mark,
count(grades.mark) AS grade_count
FROM (((public.lessons l
FROM ((((public.lessons l
JOIN public.groups g ON ((g.id = l.group_id)))
JOIN public.grades ON (((grades.lesson_id = l.id) AND (grades.deleted_at IS NULL))))
JOIN public.students s ON ((grades.student_id = s.id)))
JOIN public.enrollments en ON ((s.id = en.student_id)))
WHERE (((en.active_since)::date <= l.date) AND ((en.inactive_since IS NULL) OR ((en.inactive_since)::date >= l.date)))
GROUP BY s.id, l.id) united
JOIN public.subject_summaries su ON ((united.subject_id = su.id)));

Expand All @@ -1721,21 +1734,20 @@ CREATE OR REPLACE VIEW public.student_lesson_summaries AS
--

CREATE OR REPLACE VIEW public.group_lesson_summaries AS
SELECT l.id AS lesson_id,
l.date AS lesson_date,
SELECT slu.lesson_id,
slu.lesson_date,
gr.id AS group_id,
gr.chapter_id,
slu.subject_id,
concat(gr.group_name, ' - ', c.chapter_name) AS group_chapter_name,
(round(avg(slu.average_mark), 2))::double precision AS average_mark,
(sum(slu.grade_count))::bigint AS grade_count
FROM (((public.lessons l
JOIN public.groups gr ON ((l.group_id = gr.id)))
FROM ((public.student_lesson_summaries slu
JOIN public.groups gr ON ((slu.group_id = gr.id)))
JOIN public.chapters c ON ((gr.chapter_id = c.id)))
JOIN public.student_lesson_summaries slu ON (((l.subject_id = slu.subject_id) AND (l.group_id = slu.group_id) AND (l.date = slu.lesson_date))))
WHERE (slu.deleted_at IS NULL)
GROUP BY l.id, gr.id, c.id, slu.subject_id
ORDER BY l.date;
GROUP BY slu.lesson_id, gr.id, c.id, slu.subject_id, slu.lesson_date
ORDER BY slu.lesson_date;


--
Expand Down Expand Up @@ -2001,6 +2013,7 @@ ALTER TABLE ONLY public.users_roles
SET search_path TO "$user", public;

INSERT INTO "schema_migrations" (version) VALUES
('20240716100102'),
('20240614142029'),
('20240610074002'),
('20240531115345'),
Expand Down
36 changes: 36 additions & 0 deletions db/views/student_lesson_summaries_v07.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,36 @@
SELECT united.*, skill_count
FROM (
SELECT s.id AS student_id,
s.group_id AS group_id,
s.first_name AS first_name,
s.last_name AS last_name,
s.deleted_at AS deleted_at,
l.id AS lesson_id,
l.date AS lesson_date,
l.subject_id AS subject_id,
round(AVG(mark), 2) AS average_mark,
COUNT(mark) AS grade_count
FROM students s
JOIN groups g ON g.id = s.group_id
JOIN lessons l ON g.id = l.group_id
LEFT JOIN grades ON (grades.student_id = s.id AND grades.lesson_id = l.id AND grades.deleted_at IS NULL)
GROUP BY s.id, l.id
UNION
SELECT s.id AS student_id,
s.group_id AS group_id,
s.first_name AS first_name,
s.last_name AS last_name,
s.deleted_at AS deleted_at,
l.id AS lesson_id,
l.date AS lesson_date,
l.subject_id AS subject_id,
round(AVG(mark), 2) AS average_mark,
COUNT(mark) AS grade_count
FROM lessons l
JOIN groups g ON g.id = l.group_id
JOIN grades ON (grades.lesson_id = l.id AND grades.deleted_at IS NULL)
JOIN students s ON grades.student_id = s.id
JOIN enrollments en ON s.id = en.student_id
WHERE en.active_since::date <= l.date AND ((en.inactive_since IS NULL) OR (en.inactive_since::date >= l.date))
GROUP BY s.id, l.id
) united JOIN subject_summaries su on united.subject_id = su.id

0 comments on commit 7dcb52f

Please sign in to comment.