create table categories ( id smallserial not null, name character varying (64) not null, description text not null, primary key (id), unique (name) ); insert into categories (name, description) values ('Прикладное программное обеспечение', '[Описание категории]'), ('Системное программное обеспечение', '[Описание категории]'), ('Системы обеспечения IT-безопасности', '[Описание категории]'), ('Специализированное программное обеспечение', '[Описание категории]'); create table subcategories ( category_id smallint not null, id smallint not null, name character varying (64) not null, description text not null, foreign key (category_id) references categories on delete cascade, primary key (category_id, id), unique (category_id, name) ); create function sfx_subcategories_id_seq() returns trigger as $$ begin if new.id is null then new.id := (select coalesce(max(subcategories.id) + 1, 1) from subcategories where subcategories.category_id = new.category_id); end if; return new; end; $$ language plpgsql; create trigger subcategories_id_seq before insert on subcategories for each row execute procedure sfx_subcategories_id_seq(); insert into subcategories (category_id, name, description) values (1, 'Программы 1С', '[Описание подкатегории]'), (1, 'Программы ЭОС', '[Описание подкатегории]'), (1, 'Собственные разработки на платформе 1С', '[Описание подкатегории]'), (2, 'Продукция Astra Linux', '[Описание подкатегории]'), (2, 'Продукция Alt Linux (Базальт-СПО)', '[Описание подкатегории]'), (2, 'ПО для работы с текстом', '[Описание подкатегории]'), (2, 'МойОфис', '[Описание подкатегории]'), (3, 'Системы обеспечения сохранности данных', '[Описание подкатегории]'), (3, 'Антивирусное ПО', '[Описание подкатегории]'), (3, 'Системы защиты корпоративной информации', '[Описание подкатегории]'), (3, 'Программный комплекс «Стахановец»', '[Описание подкатегории]'), (3, 'Решение StaffCop Enterprise', '[Описание подкатегории]'), (4, 'Графические редакторы Movavi', '[Описание подкатегории]'), (4, 'Сметные программы', '[Описание подкатегории]'), (4, 'Библиотеки нормативов и стандартов', '[Описание подкатегории]'), (4, 'САПР', '[Описание подкатегории]'), (4, 'Решения для совместной работы TrueConf', '[Описание подкатегории]'), (4, 'Polys - система безопасных онлайн-голосований', '[Описание подкатегории]'), (4, 'VISOCALL IP Телекоммуникация в медицине', '[Описание подкатегории]'); create table executors ( id bigserial not null, name character varying (64) not null, primary key (id), unique (name) ); insert into executors (name) values ('Богатырёва Ю. И.'), ('Ванькова В. С.'), ('Даниленко С. В.'), ('Екатериничев А. Л.'), ('Клепиков А. К.'), ('Мартынюк Ю. М.'), ('Надеждин Е. Н.'), ('Привалов А. Н.'), ('Родионова О. В.'); create table executor_specialties ( executor_id bigint not null, category_id smallint not null, subcategory_id smallint not null, foreign key (executor_id) references executors on delete cascade, foreign key (category_id, subcategory_id) references subcategories on delete cascade, primary key (executor_id, category_id, subcategory_id) ); insert into executor_specialties (executor_id, category_id, subcategory_id) values (1, 1, 1), (2, 1, 1), (4, 1, 1), (5, 1, 1), (6, 1, 1), (7, 1, 1), (8, 1, 1), (9, 1, 1), (4, 1, 2), (5, 1, 2), (7, 1, 2), (8, 1, 2), (1, 1, 3), (2, 1, 3), (3, 1, 3), (5, 1, 3), (6, 1, 3), (7, 1, 3), (8, 1, 3), (4, 2, 1), (5, 2, 1), (6, 2, 1), (7, 2, 1), (8, 2, 1), (9, 2, 1), (2, 2, 2), (5, 2, 2), (6, 2, 2), (7, 2, 2), (8, 2, 2), (9, 2, 2), (2, 2, 3), (4, 2, 3), (8, 2, 3), (4, 2, 4), (5, 2, 4), (8, 2, 4), (9, 2, 4), (2, 3, 1), (3, 3, 1), (6, 3, 1), (7, 3, 1), (1, 3, 2), (4, 3, 2), (5, 3, 2), (6, 3, 2), (9, 3, 2), (1, 3, 3), (6, 3, 3), (9, 3, 3), (3, 3, 4), (8, 3, 4), (1, 3, 5), (3, 3, 5), (5, 3, 5), (6, 3, 5), (7, 3, 5), (9, 3, 5), (5, 4, 1), (6, 4, 1), (7, 4, 2), (9, 4, 4), (3, 4, 6), (4, 4, 6); create table time_ranges ( id smallserial not null, start_time time not null, end_time time not null, primary key (id) ); insert into time_ranges (start_time, end_time) values ('9:00'::time, '12:00'::time), ('12:00'::time, '15:00'::time), ('15:00'::time, '18:00'::time); create table orders ( id bigserial not null, category_id smallint not null, subcategory_id smallint not null, date date not null, time_range_id smallint not null, executor_id bigint not null, telegram_id bigint not null, email_address character varying (256) not null, phone_number character varying (16) not null, comment character varying (1024) not null, start_time timestamp, end_time timestamp, foreign key (category_id, subcategory_id) references subcategories on delete cascade, foreign key (time_range_id) references time_ranges on delete cascade, foreign key (executor_id) references executors on delete cascade, primary key (id) ); create table issues ( id bigint not null, key character varying (16) not null, status character varying (16) not null, telegram_id bigint not null, primary key (id), unique (key) ); create table statistics ( category_id smallint not null, subcategory_id smallint not null, execution_time interval not null, foreign key (category_id, subcategory_id) references subcategories on delete cascade, primary key (category_id, subcategory_id) ); insert into statistics (category_id, subcategory_id, execution_time) values (1, 1, interval '15 minutes'), (1, 2, interval '30 minutes'), (1, 3, interval '15 minutes'), (2, 1, interval '1 hour'), (2, 2, interval '2 hours'), (2, 3, interval '1 hour'), (2, 4, interval '2 hours'), (3, 1, interval '15 minutes'), (3, 2, interval '30 minutes'), (3, 3, interval '15 minutes'), (3, 4, interval '30 minutes'), (3, 5, interval '15 minutes'), (4, 1, interval '1 hour'), (4, 2, interval '2 hours'), (4, 3, interval '1 hour'), (4, 4, interval '2 hours'), (4, 5, interval '1 hour'), (4, 6, interval '2 hours'), (4, 7, interval '1 hour'); create or replace function sfx_update_statistics( k integer ) returns void as $$ declare subcategory subcategories; declare _order record; begin for subcategory in ( select subcategories.category_id, subcategories.id from subcategories ) loop for _order in ( select count(t1) as count, avg(t1.end_time - t1.start_time) as avg from ( select orders.start_time, orders.end_time from orders where orders.category_id = subcategory.category_id and orders.subcategory_id = subcategory.id and orders.start_time is not null and orders.end_time is not null order by orders.start_time desc limit k ) t1 ) loop if _order.count <> k then continue; end if; update statistics set execution_time = _order.avg where statistics.category_id = subcategory.category_id and statistics.subcategory_id = subcategory.id; end loop; end loop; end; $$ language plpgsql; create or replace function sfx_read_free_to_order( _category_id smallint, _subcategory_id smallint ) returns table ( date date, time_range_id smallint, executor_id bigint, busy_interval interval ) as $$ declare avg_interval interval := ( select statistics.execution_time from statistics where statistics.category_id = _category_id and statistics.subcategory_id = _subcategory_id ); declare max_interval interval := ( select max(time_ranges.end_time - time_ranges.start_time) from time_ranges ); declare executor executors; declare time_range time_ranges; declare _date date := now()::date; declare _busy_interval interval; begin if avg_interval > max_interval then raise '0x00000005'; end if; create temporary table tmp ( date date not null, time_range_id smallint not null, executor_id bigint not null, busy_interval interval not null ) on commit drop; while ( select coalesce(count(t1.*), 0) < 6 from (select distinct tmp.date from tmp) t1 ) loop for executor in ( select executors.id from executor_specialties left join executors on executor_specialties.executor_id = executors.id where executor_specialties.category_id = _category_id and executor_specialties.subcategory_id = _subcategory_id ) loop for time_range in ( select time_ranges.id, time_ranges.start_time, time_ranges.end_time from time_ranges ) loop if _date = now()::date and time_range.start_time < now()::time then continue; end if; _busy_interval := ( select coalesce(sum(statistics.execution_time), '0s'::interval) from orders left join statistics on orders.category_id = statistics.category_id and orders.subcategory_id = statistics.subcategory_id where orders.date = _date and orders.time_range_id = time_range.id and orders.executor_id = executor.id ); if time_range.end_time - time_range.start_time - _busy_interval > avg_interval then insert into tmp ( date, time_range_id, executor_id, busy_interval ) values ( _date, time_range.id, executor.id, _busy_interval ); end if; end loop; end loop; _date = _date + '1 day'::interval; end loop; return query ( select tmp.* from tmp ); end; $$ language plpgsql;