This commit is contained in:
Тимур 2025-11-12 08:54:59 +03:00
parent 331ef0ff92
commit ec95bf411e
2 changed files with 361 additions and 0 deletions

View file

@ -0,0 +1,360 @@
<?xml version="1.0" encoding="UTF-8"?>
<databaseChangeLog
xmlns="http://www.liquibase.org/xml/ns/dbchangelog/1.9"
xmlns:xsi="http://www.w3.org/2001/XMLSchema-instance"
xsi:schemaLocation="http://www.liquibase.org/xml/ns/dbchangelog/1.9
http://www.liquibase.org/xml/ns/dbchangelog/dbchangelog-1.9.xsd">
<changeSet id="0001" author="akhmetshin">
<comment>edit</comment>
<sql>
ALTER TABLE summonses_list.imposition_tmp_measures
DROP CONSTRAINT IF EXISTS fk_summonses_reason_id;
ALTER TABLE summonses_list.formed_summonses
DROP CONSTRAINT IF EXISTS fk_summonses_reason_id;
ALTER TABLE summonses_list.info_sent_to_lk_epgu
DROP CONSTRAINT IF EXISTS fk_summonses_reason_id;
ALTER TABLE summonses_list.recruit_office_visit
DROP CONSTRAINT IF EXISTS fk_summonses_reason_id;
ALTER TABLE summonses_list.remove_tmp_measures
DROP CONSTRAINT IF EXISTS fk_summonses_reason_id;
ALTER TABLE summonses_list.rf_leaving_ban
DROP CONSTRAINT IF EXISTS fk_summonses_reason_id;
CREATE TABLE IF NOT EXISTS summonses_list.imposition_tmp_measures_storage (
imposition_tmp_measures_storage_id bigserial NOT NULL,
recruitment_id varchar(36) NOT NULL,
update_date timestamp DEFAULT now() NOT NULL,
info_date date NOT NULL,
summonses_reason_id int8 NOT NULL,
count_for_sign int8 DEFAULT 0 NOT NULL,
count_apply int8 DEFAULT 0 NOT NULL,
count_enter int8 DEFAULT 0 NOT NULL,
CONSTRAINT imposition_tmp_measures_storage_pkey PRIMARY KEY (imposition_tmp_measures_storage_id)
);
CREATE index IF NOT EXISTS idx_download_for_print_reason_storage ON summonses_list.imposition_tmp_measures_storage USING btree (summonses_reason_id);
CREATE INDEX IF NOT exists idx_imposition_tmp_measures_date_storage ON summonses_list.imposition_tmp_measures_storage USING btree (info_date);
CREATE INDEX IF NOT exists idx_imposition_tmp_measures_reason_storage ON summonses_list.imposition_tmp_measures_storage USING btree (summonses_reason_id);
CREATE INDEX IF NOT exists idx_imposition_tmp_measures_recr_storage ON summonses_list.imposition_tmp_measures_storage USING btree (recruitment_id);
CREATE INDEX IF NOT exists idx_imposition_tmp_measures_recr_date_storage ON summonses_list.imposition_tmp_measures_storage USING btree (recruitment_id, info_date);
CREATE INDEX IF NOT exists idx_info_sent_to_lk_epgu_reason_storage ON summonses_list.imposition_tmp_measures_storage USING btree (summonses_reason_id);
DELETE FROM summonses_list.summonses_reason;
INSERT INTO summonses_list.summonses_reason
(summonses_reason_id, parent_summonses_reason_id, code, "name")
VALUES
(1, 1, '1', 'Первоначальная постановка на воинский учет'),
(2, 2, '2', 'Призывная кампания'),
(3, 2, '3', 'Уточнение документов воинского учета'),
(4, 2, '4', 'Прохождение медицинского освидетельствования или мероприятий, связанных с ним'),
(5, 2, '5', 'Прохождение призывной комиссии'),
(6, 2, '6', 'Отправление к месту прохождения службы'),
(7, 7, '7', 'Ведение воинского учета'),
(8, 7, '8', 'Проведение мероприятий по медицинскому освидетельствованию и обследованию'),
(9, 7, '9', 'Проведение мероприятий по профессиональному психологическому отбору граждан'),
(10, 7, '10', 'Уточнение военно-учетных данных'),
(11, 7, '11', 'Сверка сведений'),
(12, 7, '12', 'Внесение изменений в документы воинского учета'),
(13, 7, '13', 'Получение документов воинского учета'),
(14, 7, '14', 'Прохождение мероприятий по проведению военных сборов'),
(15, 7, '15', 'Прохождение повторного медицинского освидетельствования'),
(16, 16, '16', 'Мобилизация');
</sql>
</changeSet>
<changeSet id="0002" author="akhmetshin">
<comment>edit</comment>
<sql>
drop view summonses_list.view_imposition_tmp_measures;
CREATE OR REPLACE VIEW summonses_list.view_imposition_tmp_measures AS
SELECT
m.imposition_tmp_measures_id,
(m.count_for_sign + COALESCE(s.count_for_sign, 0) +
m.count_apply + COALESCE(s.count_apply, 0) +
m.count_enter + COALESCE(s.count_enter, 0)) AS count_all,
m.count_for_sign + COALESCE(s.count_for_sign, 0) as count_for_sign,
m.count_apply + COALESCE(s.count_apply, 0) as count_apply,
m.count_enter + COALESCE(s.count_enter, 0) as count_enter,
COALESCE(round((m.count_for_sign + COALESCE(s.count_for_sign, 0)) * 100.0 /
NULLIF((m.count_for_sign + COALESCE(s.count_for_sign, 0) +
m.count_apply + COALESCE(s.count_apply, 0) +
m.count_enter + COALESCE(s.count_enter, 0)), 0)), 0) AS percent_for_sign,
COALESCE(round((m.count_apply + COALESCE(s.count_apply, 0)) * 100.0 /
NULLIF((m.count_for_sign + COALESCE(s.count_for_sign, 0) +
m.count_apply + COALESCE(s.count_apply, 0) +
m.count_enter + COALESCE(s.count_enter, 0)), 0)), 0) AS percent_apply,
COALESCE(round((m.count_enter + COALESCE(s.count_enter, 0)) * 100.0 /
NULLIF((m.count_for_sign + COALESCE(s.count_for_sign, 0) +
m.count_apply + COALESCE(s.count_apply, 0) +
m.count_enter + COALESCE(s.count_enter, 0)), 0)), 0) AS percent_enter
FROM summonses_list.imposition_tmp_measures m
LEFT JOIN (
SELECT DISTINCT ON (recruitment_id, summonses_reason_id, info_date)
recruitment_id, summonses_reason_id, info_date,
count_for_sign, count_apply, count_enter
FROM summonses_list.imposition_tmp_measures_storage
ORDER BY recruitment_id, summonses_reason_id, info_date, update_date DESC
) s ON m.recruitment_id = s.recruitment_id
AND m.summonses_reason_id = s.summonses_reason_id;
</sql>
</changeSet>
<changeSet id="0003" author="akhmetshin">
<comment>edit</comment>
<sql>
CREATE TABLE IF NOT EXISTS summonses_list.rf_leaving_ban_storage (
rf_leaving_ban_storage_id bigserial NOT NULL,
recruitment_id varchar(36) NOT NULL,
update_date timestamp DEFAULT now() NOT NULL,
info_date date NOT NULL,
summonses_reason_id int8 NOT NULL,
count_for_sign int8 DEFAULT 0 NOT NULL,
count_signed int8 DEFAULT 0 NOT NULL,
count_enter int8 DEFAULT 0 NOT NULL,
CONSTRAINT rf_leaving_ban_storage_pkey PRIMARY KEY (rf_leaving_ban_storage_id)
);
-- Создаем индексы аналогичные основной таблице
CREATE INDEX IF NOT EXISTS idx_rf_leaving_ban_date_storage ON summonses_list.rf_leaving_ban_storage USING btree (info_date);
CREATE INDEX IF NOT EXISTS idx_rf_leaving_ban_reason_storage ON summonses_list.rf_leaving_ban_storage USING btree (summonses_reason_id);
CREATE INDEX IF NOT EXISTS idx_rf_leaving_ban_recr_storage ON summonses_list.rf_leaving_ban_storage USING btree (recruitment_id);
CREATE INDEX IF NOT EXISTS idx_rf_leaving_ban_recr_date_storage ON summonses_list.rf_leaving_ban_storage USING btree (recruitment_id, info_date);
drop view summonses_list.view_rf_leaving_ban;
CREATE OR REPLACE VIEW summonses_list.view_rf_leaving_ban AS
SELECT
m.rf_leaving_ban_id,
(m.count_for_sign + COALESCE(s.count_for_sign, 0) +
m.count_signed + COALESCE(s.count_signed, 0) +
m.count_enter + COALESCE(s.count_enter, 0)) AS count_all,
m.count_for_sign + COALESCE(s.count_for_sign, 0) as count_for_sign,
m.count_signed + COALESCE(s.count_signed, 0) as count_signed,
m.count_enter + COALESCE(s.count_enter, 0) as count_enter,
COALESCE(round((m.count_for_sign + COALESCE(s.count_for_sign, 0)) * 100.0 /
NULLIF((m.count_for_sign + COALESCE(s.count_for_sign, 0) +
m.count_signed + COALESCE(s.count_signed, 0) +
m.count_enter + COALESCE(s.count_enter, 0)), 0)), 0) AS percent_for_sign,
COALESCE(round((m.count_signed + COALESCE(s.count_signed, 0)) * 100.0 /
NULLIF((m.count_for_sign + COALESCE(s.count_for_sign, 0) +
m.count_signed + COALESCE(s.count_signed, 0) +
m.count_enter + COALESCE(s.count_enter, 0)), 0)), 0) AS percent_signed,
COALESCE(round((m.count_enter + COALESCE(s.count_enter, 0)) * 100.0 /
NULLIF((m.count_for_sign + COALESCE(s.count_for_sign, 0) +
m.count_signed + COALESCE(s.count_signed, 0) +
m.count_enter + COALESCE(s.count_enter, 0)), 0)), 0) AS percent_enter
FROM summonses_list.rf_leaving_ban m
LEFT JOIN (
SELECT DISTINCT ON (recruitment_id, summonses_reason_id, info_date)
recruitment_id, summonses_reason_id, info_date,
count_for_sign, count_signed, count_enter
FROM summonses_list.rf_leaving_ban_storage
ORDER BY recruitment_id, summonses_reason_id, info_date, update_date DESC
) s ON m.recruitment_id = s.recruitment_id
AND m.summonses_reason_id = s.summonses_reason_id ;
</sql>
</changeSet>
<changeSet id="0004" author="akhmetshin">
<comment>edit</comment>
<sql>
CREATE TABLE IF NOT EXISTS summonses_list.remove_tmp_measures_storage (
remove_tmp_measures_storage_id bigserial NOT NULL,
recruitment_id varchar(36) NOT NULL,
update_date timestamp DEFAULT now() NOT NULL,
info_date date NOT NULL,
summonses_reason_id int8 NOT NULL,
count_formed int8 DEFAULT 0 NOT NULL,
count_for_sign int8 DEFAULT 0 NOT NULL,
count_signed int8 DEFAULT 0 NOT NULL,
count_removed int8 DEFAULT 0 NOT NULL,
CONSTRAINT remove_tmp_measures_storage_pkey PRIMARY KEY (remove_tmp_measures_storage_id),
CONSTRAINT fk_summonses_reason_id_storage FOREIGN KEY (summonses_reason_id) REFERENCES summonses_list.summonses_reason(summonses_reason_id)
);
-- Создаем индексы аналогичные основной таблице
CREATE INDEX IF NOT EXISTS idx_remove_tmp_measures_date_storage ON summonses_list.remove_tmp_measures_storage USING btree (info_date);
CREATE INDEX IF NOT EXISTS idx_remove_tmp_measures_reason_storage ON summonses_list.remove_tmp_measures_storage USING btree (summonses_reason_id);
CREATE INDEX IF NOT EXISTS idx_remove_tmp_measures_recr_storage ON summonses_list.remove_tmp_measures_storage USING btree (recruitment_id);
CREATE INDEX IF NOT EXISTS idx_remove_tmp_measures_recr_date_storage ON summonses_list.remove_tmp_measures_storage USING btree (recruitment_id, info_date);
drop view summonses_list.view_remove_tmp_measures;
CREATE OR REPLACE VIEW summonses_list.view_remove_tmp_measures AS
SELECT
m.remove_tmp_measures_id,
(m.count_formed + COALESCE(s.count_formed, 0) +
m.count_for_sign + COALESCE(s.count_for_sign, 0) +
m.count_signed + COALESCE(s.count_signed, 0) +
m.count_removed + COALESCE(s.count_removed, 0)) AS count_all,
m.count_formed + COALESCE(s.count_formed, 0) as count_formed,
m.count_for_sign + COALESCE(s.count_for_sign, 0) as count_for_sign,
m.count_signed + COALESCE(s.count_signed, 0) as count_signed,
m.count_removed + COALESCE(s.count_removed, 0) as count_removed,
COALESCE(round((m.count_formed + COALESCE(s.count_formed, 0)) * 100.0 /
NULLIF((m.count_formed + COALESCE(s.count_formed, 0) +
m.count_for_sign + COALESCE(s.count_for_sign, 0) +
m.count_signed + COALESCE(s.count_signed, 0) +
m.count_removed + COALESCE(s.count_removed, 0)), 0)), 0) AS percent_formed,
COALESCE(round((m.count_for_sign + COALESCE(s.count_for_sign, 0)) * 100.0 /
NULLIF((m.count_formed + COALESCE(s.count_formed, 0) +
m.count_for_sign + COALESCE(s.count_for_sign, 0) +
m.count_signed + COALESCE(s.count_signed, 0) +
m.count_removed + COALESCE(s.count_removed, 0)), 0)), 0) AS percent_for_sign,
COALESCE(round((m.count_signed + COALESCE(s.count_signed, 0)) * 100.0 /
NULLIF((m.count_formed + COALESCE(s.count_formed, 0) +
m.count_for_sign + COALESCE(s.count_for_sign, 0) +
m.count_signed + COALESCE(s.count_signed, 0) +
m.count_removed + COALESCE(s.count_removed, 0)), 0)), 0) AS percent_signed,
COALESCE(round((m.count_removed + COALESCE(s.count_removed, 0)) * 100.0 /
NULLIF((m.count_formed + COALESCE(s.count_formed, 0) +
m.count_for_sign + COALESCE(s.count_for_sign, 0) +
m.count_signed + COALESCE(s.count_signed, 0) +
m.count_removed + COALESCE(s.count_removed, 0)), 0)), 0) AS percent_removed
FROM summonses_list.remove_tmp_measures m
LEFT JOIN (
SELECT DISTINCT ON (recruitment_id, summonses_reason_id, info_date)
recruitment_id, summonses_reason_id, info_date,
count_formed, count_for_sign, count_signed, count_removed
FROM summonses_list.remove_tmp_measures_storage
ORDER BY recruitment_id, summonses_reason_id, info_date, update_date DESC
) s ON m.recruitment_id = s.recruitment_id
AND m.summonses_reason_id = s.summonses_reason_id ;
</sql>
</changeSet>
<changeSet id="0005" author="akhmetshin">
<comment>edit</comment>
<sql>
CREATE TABLE IF NOT EXISTS summonses_list.info_sent_to_lk_epgu_storage (
info_sent_to_lk_epgu_storage_id bigserial NOT NULL,
recruitment_id varchar(36) NOT NULL,
update_date timestamp DEFAULT now() NOT NULL,
info_date date NOT NULL,
summonses_reason_id int8 NOT NULL,
count_status_formed int8 DEFAULT 0 NOT NULL,
count_sended int8 DEFAULT 0 NOT NULL,
count_delivered int8 DEFAULT 0 NOT NULL,
count_error int8 DEFAULT 0 NOT NULL,
count_viewed int8 DEFAULT 0 NOT NULL,
count_not_viewed int8 DEFAULT 0 NOT NULL,
count_status_not_formed int8 DEFAULT 0 NOT NULL,
count_exceeded_send int8 DEFAULT 0 NOT NULL,
count_exceeded_delivered int8 DEFAULT 0 NOT NULL,
CONSTRAINT info_sent_to_lk_epgu_storage_pkey PRIMARY KEY (info_sent_to_lk_epgu_storage_id),
CONSTRAINT fk_summonses_reason_id_storage FOREIGN KEY (summonses_reason_id) REFERENCES summonses_list.summonses_reason(summonses_reason_id)
);
-- Создаем индексы аналогичные основной таблице
CREATE INDEX IF NOT EXISTS idx_info_sent_to_lk_epgu_date_storage ON summonses_list.info_sent_to_lk_epgu_storage USING btree (info_date);
CREATE INDEX IF NOT EXISTS idx_info_sent_to_lk_epgu_recr_storage ON summonses_list.info_sent_to_lk_epgu_storage USING btree (recruitment_id);
CREATE INDEX IF NOT EXISTS idx_info_sent_to_lk_epgu_recr_date_storage ON summonses_list.info_sent_to_lk_epgu_storage USING btree (recruitment_id, info_date);
drop view summonses_list.view_info_sent_to_lk_epgu;
CREATE OR REPLACE VIEW summonses_list.view_info_sent_to_lk_epgu AS
SELECT
m.info_sent_to_lk_epgu_id,
-- Суммарные значения счетчиков
m.count_status_formed + COALESCE(s.count_status_formed, 0) as count_status_formed,
m.count_sended + COALESCE(s.count_sended, 0) as count_sended,
m.count_delivered + COALESCE(s.count_delivered, 0) as count_delivered,
m.count_error + COALESCE(s.count_error, 0) as count_error,
m.count_viewed + COALESCE(s.count_viewed, 0) as count_viewed,
m.count_not_viewed + COALESCE(s.count_not_viewed, 0) as count_not_viewed,
m.count_status_not_formed + COALESCE(s.count_status_not_formed, 0) as count_status_not_formed,
m.count_exceeded_send + COALESCE(s.count_exceeded_send, 0) as count_exceeded_send,
m.count_exceeded_delivered + COALESCE(s.count_exceeded_delivered, 0) as count_exceeded_delivered,
-- Общее количество (основа для расчета процентов)
(m.count_status_formed + COALESCE(s.count_status_formed, 0) +
m.count_status_not_formed + COALESCE(s.count_status_not_formed, 0)) AS count_all,
-- Расчет процентов
COALESCE(round((m.count_status_formed + COALESCE(s.count_status_formed, 0)) * 100.0 /
NULLIF((m.count_status_formed + COALESCE(s.count_status_formed, 0) +
m.count_status_not_formed + COALESCE(s.count_status_not_formed, 0)), 0)), 0) AS percent_status_formed,
COALESCE(round((m.count_status_not_formed + COALESCE(s.count_status_not_formed, 0)) * 100.0 /
NULLIF((m.count_status_formed + COALESCE(s.count_status_formed, 0) +
m.count_status_not_formed + COALESCE(s.count_status_not_formed, 0)), 0)), 0) AS percent_status_not_formed,
COALESCE(round((m.count_sended + COALESCE(s.count_sended, 0)) * 100.0 /
NULLIF((m.count_status_formed + COALESCE(s.count_status_formed, 0) +
m.count_status_not_formed + COALESCE(s.count_status_not_formed, 0)), 0)), 0) AS percent_sended,
COALESCE(round((m.count_delivered + COALESCE(s.count_delivered, 0)) * 100.0 /
NULLIF((m.count_status_formed + COALESCE(s.count_status_formed, 0) +
m.count_status_not_formed + COALESCE(s.count_status_not_formed, 0)), 0)), 0) AS percent_delivered,
COALESCE(round((m.count_error + COALESCE(s.count_error, 0)) * 100.0 /
NULLIF((m.count_status_formed + COALESCE(s.count_status_formed, 0) +
m.count_status_not_formed + COALESCE(s.count_status_not_formed, 0)), 0)), 0) AS percent_error,
COALESCE(round((m.count_viewed + COALESCE(s.count_viewed, 0)) * 100.0 /
NULLIF((m.count_status_formed + COALESCE(s.count_status_formed, 0) +
m.count_status_not_formed + COALESCE(s.count_status_not_formed, 0)), 0)), 0) AS percent_viewed,
COALESCE(round((m.count_not_viewed + COALESCE(s.count_not_viewed, 0)) * 100.0 /
NULLIF((m.count_status_formed + COALESCE(s.count_status_formed, 0) +
m.count_status_not_formed + COALESCE(s.count_status_not_formed, 0)), 0)), 0) AS percent_not_viewed,
COALESCE(round((m.count_exceeded_send + COALESCE(s.count_exceeded_send, 0)) * 100.0 /
NULLIF((m.count_status_formed + COALESCE(s.count_status_formed, 0) +
m.count_status_not_formed + COALESCE(s.count_status_not_formed, 0)), 0)), 0) AS percent_exceeded_send,
COALESCE(round((m.count_exceeded_delivered + COALESCE(s.count_exceeded_delivered, 0)) * 100.0 /
NULLIF((m.count_status_formed + COALESCE(s.count_status_formed, 0) +
m.count_status_not_formed + COALESCE(s.count_status_not_formed, 0)), 0)), 0) AS percent_exceeded_delivered
FROM summonses_list.info_sent_to_lk_epgu m
LEFT JOIN (
SELECT DISTINCT ON (recruitment_id, summonses_reason_id, info_date)
recruitment_id, summonses_reason_id, info_date,
count_status_formed, count_sended, count_delivered, count_error,
count_viewed, count_not_viewed, count_status_not_formed,
count_exceeded_send, count_exceeded_delivered
FROM summonses_list.info_sent_to_lk_epgu_storage
ORDER BY recruitment_id, summonses_reason_id, info_date, update_date DESC
) s ON m.recruitment_id = s.recruitment_id
AND m.summonses_reason_id = s.summonses_reason_id;
</sql>
</changeSet>
</databaseChangeLog>

View file

@ -39,4 +39,5 @@
<include file="20250530-SUPPORT-9212_idmv3.xml" relativeToChangelogFile="true"/>
<include file="20250815-view_fix.xml" relativeToChangelogFile="true"/>
<include file="20250821-last_recording_date.xml" relativeToChangelogFile="true"/>
<include file="20251111-create_tables_for_summons_list.xml" relativeToChangelogFile="true"/>
</databaseChangeLog>