|
@@ -0,0 +1,357 @@
|
|
|
+-- tables
|
|
|
+
|
|
|
+CREATE TABLE public."groups" (
|
|
|
+ group_id serial4 NOT NULL,
|
|
|
+ title varchar(8) NOT NULL,
|
|
|
+ CONSTRAINT groups_pk PRIMARY KEY (group_id),
|
|
|
+ CONSTRAINT groups_un UNIQUE (title)
|
|
|
+);
|
|
|
+
|
|
|
+CREATE TABLE public.types_of_payments (
|
|
|
+ type_of_payment_id serial4 NOT NULL,
|
|
|
+ type_tittle varchar(60) NOT NULL,
|
|
|
+ CONSTRAINT types_of_payments_pk PRIMARY KEY (type_of_payment_id),
|
|
|
+ CONSTRAINT types_of_payments_unique UNIQUE (type_of_payment_id)
|
|
|
+);
|
|
|
+
|
|
|
+CREATE TABLE public.students_status (
|
|
|
+ status_id serial4 NOT NULL,
|
|
|
+ title varchar(40) NOT NULL,
|
|
|
+ CONSTRAINT students_status_pk PRIMARY KEY (status_id)
|
|
|
+);
|
|
|
+
|
|
|
+CREATE TABLE public.students (
|
|
|
+ student_id serial4 NOT NULL,
|
|
|
+ "name" varchar(64) NOT NULL,
|
|
|
+ surname varchar(64) NOT NULL,
|
|
|
+ student_group_id serial4 NOT NULL,
|
|
|
+ patronymic varchar(64) NULL,
|
|
|
+ admission_date int2 NULL,
|
|
|
+ student_status_id serial4 NOT NULL,
|
|
|
+ fio text NULL,
|
|
|
+ CONSTRAINT students_pk PRIMARY KEY (student_id),
|
|
|
+ CONSTRAINT students_unique UNIQUE (fio, admission_date, student_status_id, student_group_id),
|
|
|
+ CONSTRAINT students_groups_fk FOREIGN KEY (student_group_id) REFERENCES public."groups"(group_id) ON UPDATE CASCADE,
|
|
|
+ CONSTRAINT students_students_status_fk FOREIGN KEY (student_status_id) REFERENCES public.students_status(status_id) ON UPDATE CASCADE
|
|
|
+);
|
|
|
+
|
|
|
+CREATE TABLE public.students_partitioned (
|
|
|
+ student_id serial4 NOT NULL,
|
|
|
+ student_group_id serial4 NOT NULL,
|
|
|
+ admission_date int2 NOT NULL,
|
|
|
+ fio text NOT NULL,
|
|
|
+ student_status_id int4 NOT NULL
|
|
|
+)
|
|
|
+PARTITION BY LIST (student_status_id);
|
|
|
+
|
|
|
+-- СНАЧАЛА ПАРТИЦИЯ потом функция update_students_partitioned -> потом уже триггер
|
|
|
+
|
|
|
+
|
|
|
+CREATE OR REPLACE FUNCTION public.update_students_partitioned()
|
|
|
+ RETURNS trigger
|
|
|
+ LANGUAGE plpgsql
|
|
|
+AS $function$
|
|
|
+BEGIN
|
|
|
+ IF (TG_OP = 'INSERT') THEN
|
|
|
+ INSERT INTO public.students_partitioned VALUES (NEW.student_id, NEW.student_group_id, NEW.admission_date, NEW.fio, NEW.student_status_id);
|
|
|
+ elsif (TG_OP = 'UPDATE') then
|
|
|
+ UPDATE public.students_partitioned
|
|
|
+ SET student_group_id = NEW.student_group_id,
|
|
|
+ admission_date = NEW.admission_date,
|
|
|
+ fio = NEW.fio,
|
|
|
+ student_status_id = NEW.student_status_id
|
|
|
+ WHERE student_id = OLD.student_id;
|
|
|
+ ELSIF (TG_OP = 'DELETE') THEN
|
|
|
+ DELETE FROM public.students_partitioned WHERE student_id = OLD.student_id;
|
|
|
+ END IF;
|
|
|
+ RETURN NULL;
|
|
|
+END;
|
|
|
+$function$
|
|
|
+;
|
|
|
+
|
|
|
+
|
|
|
+-- Table Triggers
|
|
|
+
|
|
|
+create trigger students_partitioned_trigger after
|
|
|
+insert
|
|
|
+ or
|
|
|
+delete
|
|
|
+ or
|
|
|
+update
|
|
|
+ on
|
|
|
+ public.students for each row execute function update_students_partitioned();
|
|
|
+
|
|
|
+
|
|
|
+CREATE TABLE public.students_and_payments (
|
|
|
+ student_payment_id bigserial NOT NULL,
|
|
|
+ student_id serial4 NOT NULL,
|
|
|
+ type_payment_id serial4 NOT NULL,
|
|
|
+ amount_payment money NOT NULL,
|
|
|
+ data_of_payment date NOT NULL
|
|
|
+)
|
|
|
+PARTITION BY RANGE (data_of_payment);
|
|
|
+
|
|
|
+
|
|
|
+-- functions
|
|
|
+
|
|
|
+
|
|
|
+CREATE OR REPLACE FUNCTION public.find_students_by_payment_date_range(start_date date, end_date date)
|
|
|
+ RETURNS TABLE(student_id integer, name character varying, surname character varying, student_group_id integer, patronymic character varying, admission_date smallint, student_status_id integer, fio text)
|
|
|
+ LANGUAGE plpgsql
|
|
|
+AS $function$
|
|
|
+BEGIN
|
|
|
+ RETURN QUERY
|
|
|
+ SELECT DISTINCT s.student_id, s.name, s.surname, s.student_group_id, s.patronymic, s.admission_date, s.student_status_id, s.fio
|
|
|
+ FROM students s
|
|
|
+ WHERE s.student_id IN (
|
|
|
+ SELECT sap.student_id
|
|
|
+ FROM students_and_payments sap
|
|
|
+ where sap.data_of_payment between start_date AND end_date
|
|
|
+ );
|
|
|
+END;
|
|
|
+$function$
|
|
|
+;
|
|
|
+
|
|
|
+CREATE OR REPLACE FUNCTION public.find_students_by_payment_end_date(end_date date)
|
|
|
+ RETURNS TABLE(student_id integer, name character varying, surname character varying, student_group_id integer, patronymic character varying, admission_date smallint, student_status_id integer, fio text)
|
|
|
+ LANGUAGE plpgsql
|
|
|
+AS $function$
|
|
|
+BEGIN
|
|
|
+ RETURN QUERY
|
|
|
+ SELECT DISTINCT s.student_id, s.name, s.surname, s.student_group_id, s.patronymic, s.admission_date, s.student_status_id, s.fio
|
|
|
+ FROM students s
|
|
|
+ WHERE s.student_id IN (
|
|
|
+ SELECT sap.student_id
|
|
|
+ FROM students_and_payments sap
|
|
|
+ where sap.data_of_payment <= end_date
|
|
|
+ );
|
|
|
+END;
|
|
|
+$function$
|
|
|
+;
|
|
|
+
|
|
|
+
|
|
|
+CREATE OR REPLACE FUNCTION public.find_students_by_payment_start_date(start_date date)
|
|
|
+ RETURNS TABLE(student_id integer, name character varying, surname character varying, student_group_id integer, patronymic character varying, admission_date smallint, student_status_id integer, fio text)
|
|
|
+ LANGUAGE plpgsql
|
|
|
+AS $function$
|
|
|
+BEGIN
|
|
|
+ RETURN QUERY
|
|
|
+ SELECT DISTINCT s.student_id, s.name, s.surname, s.student_group_id, s.patronymic, s.admission_date, s.student_status_id, s.fio
|
|
|
+ FROM students s
|
|
|
+ WHERE s.student_id IN (
|
|
|
+ SELECT sap.student_id
|
|
|
+ FROM students_and_payments sap
|
|
|
+ where sap.data_of_payment >= start_date
|
|
|
+ );
|
|
|
+END;
|
|
|
+$function$
|
|
|
+;
|
|
|
+
|
|
|
+CREATE OR REPLACE FUNCTION public.get_count_students_by_group(group_id integer)
|
|
|
+ RETURNS integer
|
|
|
+ LANGUAGE plpgsql
|
|
|
+AS $function$
|
|
|
+declare
|
|
|
+ student_count int;
|
|
|
+
|
|
|
+begin
|
|
|
+ select count(*)
|
|
|
+ into student_count
|
|
|
+ from students
|
|
|
+ where student_group_id = group_id;
|
|
|
+
|
|
|
+ return student_count;
|
|
|
+end;
|
|
|
+$function$
|
|
|
+;
|
|
|
+
|
|
|
+CREATE OR REPLACE FUNCTION public.get_students_by_group_id(group_id_arg integer)
|
|
|
+ RETURNS TABLE(student_id integer, name character varying, surname character varying, student_group_id integer, patronymic character varying, admission_date smallint, student_status_id integer, fio text)
|
|
|
+ LANGUAGE plpgsql
|
|
|
+AS $function$
|
|
|
+BEGIN
|
|
|
+ RETURN QUERY SELECT s.student_id, s.name, s.surname, s.student_group_id, s.patronymic, s.admission_date, s.student_status_id, s.fio
|
|
|
+ FROM students s
|
|
|
+ WHERE s.student_group_id = group_id_arg;
|
|
|
+END;
|
|
|
+$function$
|
|
|
+;
|
|
|
+
|
|
|
+CREATE OR REPLACE FUNCTION public.get_students_by_status(status_id_arg integer)
|
|
|
+ RETURNS TABLE(student_id integer, name character varying, surname character varying, student_group_id integer, patronymic character varying, admission_date smallint, student_status_id integer, fio text)
|
|
|
+ LANGUAGE plpgsql
|
|
|
+AS $function$
|
|
|
+BEGIN
|
|
|
+ RETURN QUERY SELECT s.student_id, s.name, s.surname, s.student_group_id, s.patronymic, s.admission_date, s.student_status_id, s.fio
|
|
|
+ FROM students s
|
|
|
+ WHERE s.student_status_id = status_id_arg;
|
|
|
+END;
|
|
|
+$function$
|
|
|
+;
|
|
|
+
|
|
|
+CREATE OR REPLACE FUNCTION public.insert_missing_students(new_students jsonb)
|
|
|
+ RETURNS void
|
|
|
+ LANGUAGE plpgsql
|
|
|
+AS $function$
|
|
|
+DECLARE
|
|
|
+ new_student RECORD;
|
|
|
+BEGIN
|
|
|
+ FOR new_student IN SELECT * FROM jsonb_populate_recordset(NULL::students, new_students)
|
|
|
+ LOOP
|
|
|
+ -- Проверяем, существует ли уже запись в таблице students
|
|
|
+ IF NOT EXISTS (
|
|
|
+ SELECT 1 FROM students
|
|
|
+ WHERE fio = new_student.fio
|
|
|
+ AND admission_date = new_student.admission_date
|
|
|
+ AND student_group_id = new_student.student_group_id
|
|
|
+ AND patronymic = new_student.patronymic
|
|
|
+ AND student_status_id = new_student.student_status_id
|
|
|
+ ) THEN
|
|
|
+ -- Если запись не найдена, вставляем новую
|
|
|
+ INSERT INTO students (
|
|
|
+ fio, name, surname, admission_date, student_group_id, patronymic, student_status_id
|
|
|
+ ) VALUES (
|
|
|
+ new_student.fio, new_student.name, new_student.surname,
|
|
|
+ new_student.admission_date, new_student.student_group_id,
|
|
|
+ new_student.patronymic, new_student.student_status_id
|
|
|
+ );
|
|
|
+ END IF;
|
|
|
+ END LOOP;
|
|
|
+END;
|
|
|
+$function$
|
|
|
+;
|
|
|
+
|
|
|
+CREATE OR REPLACE FUNCTION public.new_payments_partition(year_arg integer)
|
|
|
+ RETURNS void
|
|
|
+ LANGUAGE plpgsql
|
|
|
+AS $function$
|
|
|
+DECLARE
|
|
|
+ partition_name TEXT;
|
|
|
+BEGIN
|
|
|
+ partition_name := 'students_and_payments_' || year_arg;
|
|
|
+
|
|
|
+ -- проверка существования партиции
|
|
|
+ IF NOT EXISTS (SELECT 1 FROM information_schema.tables WHERE table_name = partition_name) THEN
|
|
|
+
|
|
|
+ EXECUTE 'CREATE TABLE ' || partition_name ||
|
|
|
+ ' PARTITION OF students_and_payments FOR VALUES FROM (DATE ''' || year_arg ||
|
|
|
+ '-01-01'') TO (DATE ''' || year_arg+1 || '-01-01'')';
|
|
|
+
|
|
|
+ EXECUTE 'ALTER TABLE ' || partition_name || ' ADD CONSTRAINT '
|
|
|
+ || partition_name || '_check_date ' ||
|
|
|
+ 'CHECK (data_of_payment >= DATE ''' || year_arg || '-01-01'' AND data_of_payment <= DATE ''' || year_arg +1
|
|
|
+ || '-01-01'')';
|
|
|
+
|
|
|
+ execute 'alter table ' || partition_name || ' add CONSTRAINT ' || partition_name || '_check_pk '||
|
|
|
+ 'PRIMARY KEY (student_payment_id)';
|
|
|
+
|
|
|
+ execute 'alter table ' || partition_name || ' add CONSTRAINT ' || partition_name || '_type_payment_fk '||
|
|
|
+ 'FOREIGN KEY (type_payment_id) REFERENCES public.types_of_payments(type_of_payment_id);';
|
|
|
+
|
|
|
+ RAISE NOTICE 'создана партиция %', partition_name;
|
|
|
+ ELSE
|
|
|
+ RAISE NOTICE 'партиция % уже существует', partition_name;
|
|
|
+ END IF;
|
|
|
+END;
|
|
|
+$function$
|
|
|
+;
|
|
|
+
|
|
|
+CREATE OR REPLACE FUNCTION public.search_students_by_fio(search_text text)
|
|
|
+ RETURNS TABLE(student_id integer, name character varying, surname character varying, student_group_id integer, patronymic character varying, admission_date smallint, student_status_id integer, fio text)
|
|
|
+ LANGUAGE plpgsql
|
|
|
+AS $function$
|
|
|
+begin
|
|
|
+ RETURN QUERY SELECT s.student_id, s.name, s.surname, s.student_group_id, s.patronymic, s.admission_date, s.student_status_id, s.fio
|
|
|
+ FROM students s
|
|
|
+ where s.fio ilike '%' || search_text || '%';
|
|
|
+end;
|
|
|
+$function$
|
|
|
+;
|
|
|
+
|
|
|
+CREATE OR REPLACE FUNCTION public.students_and_payments_insert_trigger()
|
|
|
+ RETURNS trigger
|
|
|
+ LANGUAGE plpgsql
|
|
|
+AS $function$
|
|
|
+begin
|
|
|
+ if (new.data_of_payment between date'2024-01-01' and date'2025-01-01'-1) then
|
|
|
+ insert into students_and_payments_2024 values (new.*); -- 2024
|
|
|
+
|
|
|
+ elsif (new.data_of_payment between date'2025-01-01' and date'2026-01-01-1'-1) then
|
|
|
+ insert into students_and_payments_2025 values (new.*);-- 2025
|
|
|
+
|
|
|
+ elsif (new.data_of_payment between date'2026-01-01' and date'2027-01-01'-1) then
|
|
|
+ insert into students_and_payments_2026 values (new.*); --2026
|
|
|
+
|
|
|
+ elsif (new.data_of_payment between date'2027-01-01' and date'2028-01-01'-1) then
|
|
|
+ insert into students_and_payments_2027 values (new.*); --2027
|
|
|
+
|
|
|
+ elsif (new.data_of_payment between date'2023-01-01' and date'2024-01-01'-1) then
|
|
|
+ insert into students_and_payments_2023 values (new.*); -- 2023
|
|
|
+
|
|
|
+ elsif (new.data_of_payment between date'2022-01-01' and date'2021-01-01'-1) then
|
|
|
+ insert into students_and_payments_2022 values (new.*); -- 2022
|
|
|
+
|
|
|
+ elsif (new.data_of_payment between date'2021-01-01' and date'2022-01-01'-1) then
|
|
|
+ insert into students_and_payments_2021 values (new.*); -- 2021
|
|
|
+
|
|
|
+ elsif (new.data_of_payment between '2020-01-01' and date'2021-01-01'-1) then
|
|
|
+ insert into students_and_payments_2020 values (new.*); -- 2020
|
|
|
+
|
|
|
+ elsif (new.data_of_payment between '2019-01-01' and '2020-01-01'-1) then
|
|
|
+ insert into students_and_payments_2019 values (new.*); -- 2019
|
|
|
+
|
|
|
+ else
|
|
|
+ raise exception 'Date out of range. Fix the students_and_payments_insert_trigger!';
|
|
|
+end if;
|
|
|
+end;
|
|
|
+
|
|
|
+$function$
|
|
|
+;
|
|
|
+
|
|
|
+CREATE OR REPLACE FUNCTION public.update_students_name()
|
|
|
+ RETURNS trigger
|
|
|
+ LANGUAGE plpgsql
|
|
|
+AS $function$
|
|
|
+begin
|
|
|
+ new.fio = concat(new.name, ' ', new.surname, ' ', new.patronymic);
|
|
|
+ return new;
|
|
|
+end;
|
|
|
+$function$
|
|
|
+;
|
|
|
+
|
|
|
+
|
|
|
+ -- view
|
|
|
+
|
|
|
+ CREATE OR REPLACE VIEW public.view_count_students_in_group
|
|
|
+AS SELECT student_group_id,
|
|
|
+ count(*) AS students_count
|
|
|
+ FROM students
|
|
|
+ GROUP BY student_group_id;
|
|
|
+
|
|
|
+
|
|
|
+ -- partitions
|
|
|
+
|
|
|
+ CREATE TABLE public.students_active_and_graduation PARTITION OF public.students_partitioned FOR VALUES IN (3, 4);
|
|
|
+
|
|
|
+ CREATE TABLE public.students_ended PARTITION OF public.students_partitioned FOR VALUES IN (5);
|
|
|
+
|
|
|
+ CREATE TABLE public.students_leaved PARTITION OF public.students_partitioned FOR VALUES IN (1, 2);
|
|
|
+
|
|
|
+ CREATE TABLE public.students_and_payments_2019 PARTITION OF public.students_and_payments (
|
|
|
+ CONSTRAINT students_and_payments_2019_check_date CHECK (((data_of_payment >= '2019-01-01'::date) AND (data_of_payment <= '2020-01-01'::date))),
|
|
|
+ CONSTRAINT students_and_payments_2019_check_pk PRIMARY KEY (student_payment_id)
|
|
|
+) FOR VALUES FROM ('2019-01-01') TO ('2020-01-01');
|
|
|
+
|
|
|
+
|
|
|
+-- создание партиции для выплат
|
|
|
+
|
|
|
+select * from new_payments_partition(2019);
|
|
|
+select * from new_payments_partition(2020);
|
|
|
+select * from new_payments_partition(2021);
|
|
|
+select * from new_payments_partition(2022);
|
|
|
+select * from new_payments_partition(2023);
|
|
|
+select * from new_payments_partition(2024);
|
|
|
+select * from new_payments_partition(2025);
|
|
|
+select * from new_payments_partition(2026);
|
|
|
+select * from new_payments_partition(2027);
|
|
|
+
|