diff --git a/backend/src/main/resources/config/v_1.0/20241031-ERVU-168_create_db.xml b/backend/src/main/resources/config/v_1.0/20241031-ERVU-168_create_db.xml index 7827b1f..ec50c30 100644 --- a/backend/src/main/resources/config/v_1.0/20241031-ERVU-168_create_db.xml +++ b/backend/src/main/resources/config/v_1.0/20241031-ERVU-168_create_db.xml @@ -1278,7 +1278,319 @@ - + + create SCHEMA deregistration + + CREATE SCHEMA IF NOT EXISTS deregistration; + + CREATE TABLE IF NOT EXISTS deregistration.data_from_gir_vu + ( + data_from_gir_vu_id bigserial NOT NULL PRIMARY KEY, + recruitment_id varchar(36) NOT NULL constraint fk_criminal_administrative_liability_recruitment_id references metrics.recruitment, + update_date timestamp without time zone NOT NULL DEFAULT now(), + info_date date NOT NULL, + count_arrived_death_reason bigint NOT NULL DEFAULT 0, + count_arrived_age_limit bigint NOT NULL DEFAULT 0, + count_formed_death_reason bigint NOT NULL DEFAULT 0, + count_formed_age_limit bigint NOT NULL DEFAULT 0, + count_for_sign_death_reason bigint NOT NULL DEFAULT 0, + count_for_sign_age_limit bigint NOT NULL DEFAULT 0 + ) + WITH (OIDS = FALSE); + ALTER TABLE IF EXISTS deregistration.data_from_gir_vu OWNER to ervu_business_metrics; + + COMMENT ON TABLE deregistration.data_from_gir_vu IS 'Снятие с воинского учета. Сведения из ГИР ВУ'; + + CREATE INDEX IF NOT EXISTS idx_records_about_citizen_date ON deregistration.data_from_gir_vu (info_date); + CREATE INDEX IF NOT EXISTS idx_data_from_gir_vu_recr ON deregistration.data_from_gir_vu (recruitment_id); + CREATE INDEX IF NOT EXISTS idx_data_from_gir_vu_recr_date ON deregistration.data_from_gir_vu (recruitment_id, info_date); + + COMMENT ON COLUMN deregistration.data_from_gir_vu.count_arrived_death_reason IS 'поступило по причине смерти'; + COMMENT ON COLUMN deregistration.data_from_gir_vu.count_arrived_age_limit IS 'поступило по предельному возрасту'; + COMMENT ON COLUMN deregistration.data_from_gir_vu.count_formed_death_reason IS 'решений сформировано по причине смерти'; + COMMENT ON COLUMN deregistration.data_from_gir_vu.count_formed_age_limit IS 'решений сформировано по предельному возрасту'; + COMMENT ON COLUMN deregistration.data_from_gir_vu.count_for_sign_death_reason IS 'решений на подписании по причине смерти'; + COMMENT ON COLUMN deregistration.data_from_gir_vu.count_for_sign_age_limit IS 'решений на подписании по предельному возрасту'; + + CREATE OR REPLACE VIEW deregistration.view_data_from_gir_vu AS + SELECT + data_from_gir_vu_id, + count_arrived_death_reason + count_arrived_age_limit AS count_arrived_all, + count_formed_death_reason + count_formed_age_limit AS count_formed_all, + count_for_sign_death_reason + count_for_sign_age_limit AS count_for_sign_all, + round(count_arrived_death_reason::numeric * 100 / (count_arrived_death_reason + count_arrived_age_limit)) AS percent_arrived_death_reason, + round(count_arrived_age_limit::numeric * 100 / (count_arrived_death_reason + count_arrived_age_limit)) AS percent_arrived_age_limit, + round(count_formed_death_reason::numeric * 100 / (count_formed_death_reason + count_formed_age_limit)) AS percent_formed_death_reason, + round(count_formed_age_limit::numeric * 100 / (count_formed_death_reason + count_formed_age_limit)) AS percent_formed_age_limit, + round(count_for_sign_death_reason::numeric * 100 / (count_for_sign_death_reason + count_for_sign_age_limit)) AS percent_for_sign_death_reason, + round(count_for_sign_age_limit::numeric * 100 / (count_for_sign_death_reason + count_for_sign_age_limit)) AS percent_for_sign_age_limit + FROM deregistration.data_from_gir_vu; + + + CREATE TABLE IF NOT EXISTS deregistration.solutions + ( + solutions_id bigserial NOT NULL PRIMARY KEY, + recruitment_id varchar(36) NOT NULL constraint fk_criminal_administrative_liability_recruitment_id references metrics.recruitment, + update_date timestamp without time zone NOT NULL DEFAULT now(), + info_date date NOT NULL, + info_source character varying NOT NULL, + count_accepted_signed bigint NOT NULL DEFAULT 0, + count_accepted_for_sign bigint NOT NULL DEFAULT 0, + count_refused_signed bigint NOT NULL DEFAULT 0, + count_refused_for_sign bigint NOT NULL DEFAULT 0 + ) + WITH (OIDS = FALSE); + ALTER TABLE IF EXISTS deregistration.solutions OWNER to ervu_business_metrics; + + COMMENT ON TABLE deregistration.solutions IS 'Снятие с воинского учета. Решение о снятии с ВУ'; + + CREATE INDEX IF NOT EXISTS idx_records_about_citizen_date ON deregistration.solutions (info_date); + CREATE INDEX IF NOT EXISTS idx_solutions_recr ON deregistration.solutions (recruitment_id); + CREATE INDEX IF NOT EXISTS idx_solutions_recr_date ON deregistration.solutions (recruitment_id, info_date); + + COMMENT ON COLUMN deregistration.solutions.info_source IS 'информация об источнике - PERSONAL_VISIT, GIR_VU, EPGU'; + COMMENT ON COLUMN deregistration.solutions.count_accepted_signed IS 'решений о снятии подписано'; + COMMENT ON COLUMN deregistration.solutions.count_accepted_for_sign IS 'решений о снятии доступно для подписания'; + COMMENT ON COLUMN deregistration.solutions.count_refused_signed IS 'решений об отказе в снятии подписано'; + COMMENT ON COLUMN deregistration.solutions.count_refused_for_sign IS 'решений об отказе в снятии доступно для подписания'; + + CREATE OR REPLACE VIEW deregistration.view_solutions AS + SELECT + solutions_id, + count_accepted_signed + count_accepted_for_sign AS count_accepted_all, + count_refused_signed + count_refused_for_sign AS count_refused_all, + round(count_accepted_signed::numeric * 100 / (count_accepted_signed + count_accepted_for_sign)) AS percent_accepted_signed, + round(count_accepted_for_sign::numeric * 100 / (count_accepted_signed + count_accepted_for_sign)) AS percent_accepted_for_sign, + round(count_refused_signed::numeric * 100 / (count_refused_signed + count_refused_for_sign)) AS percent_refused_signed, + round(count_refused_for_sign::numeric * 100 / (count_refused_signed + count_refused_for_sign)) AS percent_refused_for_sign + FROM deregistration.solutions; + + + CREATE TABLE IF NOT EXISTS deregistration.info_sent_to_lk_epgu + ( + info_sent_to_lk_epgu_id bigserial NOT NULL PRIMARY KEY, + recruitment_id varchar(36) NOT NULL constraint fk_conv_info_records_from_easu_recruitment_id references metrics.recruitment, + update_date timestamp without time zone NOT NULL DEFAULT now(), + info_date date NOT NULL, + info_source character varying NOT NULL, + count_status_formed bigint NOT NULL DEFAULT 0, + count_sended bigint NOT NULL DEFAULT 0, + count_delivered bigint NOT NULL DEFAULT 0, + count_error bigint NOT NULL DEFAULT 0, + count_viewed bigint NOT NULL DEFAULT 0, + count_not_viewed bigint NOT NULL DEFAULT 0, + count_status_not_formed bigint NOT NULL DEFAULT 0 + ) + WITH (OIDS = FALSE); + ALTER TABLE IF EXISTS deregistration.info_sent_to_lk_epgu OWNER to ervu_business_metrics; + + COMMENT ON TABLE deregistration.info_sent_to_lk_epgu IS 'Снятие с воинского учета. Отправка уведомлений в ЛК на ЕПГУ'; + + CREATE INDEX IF NOT EXISTS idx_info_sent_to_lk_epgu_date ON deregistration.info_sent_to_lk_epgu (info_date); + CREATE INDEX IF NOT EXISTS idx_info_sent_to_lk_epgu_recr ON deregistration.info_sent_to_lk_epgu (recruitment_id); + CREATE INDEX IF NOT EXISTS idx_info_sent_to_lk_epgu_recr_date ON deregistration.info_sent_to_lk_epgu (recruitment_id, info_date); + + CREATE OR REPLACE VIEW deregistration.view_info_sent_to_lk_epgu AS + SELECT + info_sent_to_lk_epgu_id, + round(count_status_formed::numeric * 100 / (count_status_formed + count_status_not_formed)) AS percent_status_formed, + round(count_status_not_formed::numeric * 100 / (count_status_formed + count_status_not_formed)) AS percent_status_not_formed, + round(count_sended::numeric* 100 / (count_status_formed + count_status_not_formed)) AS percent_sended, + round(count_delivered::numeric * 100 / (count_status_formed + count_status_not_formed)) AS percent_delivered, + round(count_error::numeric * 100 / (count_status_formed + count_status_not_formed)) AS percent_error, + round(count_viewed::numeric * 100 / (count_status_formed + count_status_not_formed)) AS percent_viewed, + round(count_not_viewed::numeric * 100 / (count_status_formed + count_status_not_formed)) AS percent_not_viewed + FROM deregistration.info_sent_to_lk_epgu; + + + + CREATE TABLE IF NOT EXISTS deregistration.applications_sent_from_epgu + ( + applications_sent_from_epgu_id bigserial NOT NULL PRIMARY KEY, + recruitment_id varchar(36) NOT NULL constraint fk_conv_info_records_from_easu_recruitment_id references metrics.recruitment, + update_date timestamp without time zone NOT NULL DEFAULT now(), + info_date date NOT NULL, + count_moved_residence bigint NOT NULL DEFAULT 0, + count_departure_more_6_month bigint NOT NULL DEFAULT 0, + count_health_condition bigint NOT NULL DEFAULT 0, + count_age_limit bigint NOT NULL DEFAULT 0 + ) + WITH (OIDS = FALSE); + ALTER TABLE IF EXISTS deregistration.applications_sent_from_epgu OWNER to ervu_business_metrics; + + COMMENT ON TABLE deregistration.applications_sent_from_epgu IS 'Снятие с воинского учета. Отправленные заявления ЕПГУ'; + + CREATE INDEX IF NOT EXISTS idx_applications_sent_from_epgu_date ON deregistration.applications_sent_from_epgu (info_date); + CREATE INDEX IF NOT EXISTS idx_applications_sent_from_epgu_recr ON deregistration.applications_sent_from_epgu (recruitment_id); + CREATE INDEX IF NOT EXISTS idx_applications_sent_from_epgu_recr_date ON deregistration.applications_sent_from_epgu (recruitment_id, info_date); + + CREATE OR REPLACE VIEW deregistration.view_applications_sent_from_epgu AS + SELECT + applications_sent_from_epgu_id, + count_moved_residence + count_departure_more_6_month + count_health_condition + count_age_limit AS count_all, + round(count_moved_residence::numeric * 100 / (count_moved_residence + count_departure_more_6_month + count_health_condition + count_age_limit)) AS percent_moved_residence, + round(count_departure_more_6_month::numeric * 100 / (count_moved_residence + count_departure_more_6_month + count_health_condition + count_age_limit)) AS percent_departure_more_6_month, + round(count_health_condition::numeric * 100 / (count_moved_residence + count_departure_more_6_month + count_health_condition + count_age_limit)) AS percent_health_condition, + round(count_age_limit::numeric * 100 / (count_moved_residence + count_departure_more_6_month + count_health_condition + count_age_limit)) AS percent_age_limit + FROM deregistration.applications_sent_from_epgu; + + + CREATE TABLE IF NOT EXISTS deregistration.applications_received_from_epgu + ( + applications_received_from_epgu_id bigserial NOT NULL PRIMARY KEY, + recruitment_id varchar(36) NOT NULL constraint fk_conv_info_records_from_easu_recruitment_id references metrics.recruitment, + update_date timestamp without time zone NOT NULL DEFAULT now(), + info_date date NOT NULL, + count_all bigint NOT NULL DEFAULT 0, + count_executor_appointed bigint NOT NULL DEFAULT 0, + count_registered bigint NOT NULL DEFAULT 0, + count_registration_refusal bigint NOT NULL DEFAULT 0, + count_refusal_provide_service bigint NOT NULL DEFAULT 0 + ) + WITH (OIDS = FALSE); + ALTER TABLE IF EXISTS deregistration.applications_received_from_epgu OWNER to ervu_business_metrics; + + COMMENT ON TABLE deregistration.applications_received_from_epgu IS 'Снятие с воинского учета. Заявления, поступившие из ЕПГУ'; + + COMMENT ON COLUMN deregistration.applications_received_from_epgu.count_executor_appointed IS 'Назначен исполнитель'; + COMMENT ON COLUMN deregistration.applications_received_from_epgu.count_registered IS 'Зарегистрировано заявлений'; + COMMENT ON COLUMN deregistration.applications_received_from_epgu.count_registration_refusal IS 'Получен отказ в регистрации'; + COMMENT ON COLUMN deregistration.applications_received_from_epgu.count_refusal_provide_service IS 'Получен отказ в предоставлении услуги'; + + CREATE INDEX IF NOT EXISTS idx_applications_received_from_epgu_date ON deregistration.applications_received_from_epgu (info_date); + CREATE INDEX IF NOT EXISTS idx_applications_received_from_epgu_recr ON deregistration.applications_received_from_epgu (recruitment_id); + CREATE INDEX IF NOT EXISTS idx_applications_received_from_epgu_recr_date ON deregistration.applications_received_from_epgu (recruitment_id, info_date); + + CREATE OR REPLACE VIEW deregistration.view_applications_received_from_epgu AS + SELECT + applications_received_from_epgu_id, + round(count_executor_appointed::numeric * 100 / count_all) AS percent_executor_appointed, + round(count_registered::numeric * 100 / count_all) AS percent_registered, + round(count_registration_refusal::numeric * 100 / count_all) AS percent_registration_refusal, + round(count_refusal_provide_service::numeric * 100 / count_all) AS percent_refusal_provide_service + FROM deregistration.applications_received_from_epgu; + + + CREATE TABLE IF NOT EXISTS deregistration.incidents_info + ( + incidents_info_id bigserial NOT NULL PRIMARY KEY, + recruitment_id varchar(36) NOT NULL constraint fk_conv_info_records_from_easu_recruitment_id references metrics.recruitment, + update_date timestamp without time zone NOT NULL DEFAULT now(), + info_date date NOT NULL, + count_for_sign bigint NOT NULL DEFAULT 0, + count_signed bigint NOT NULL DEFAULT 0 + ) + WITH (OIDS = FALSE); + ALTER TABLE IF EXISTS deregistration.incidents_info OWNER to ervu_business_metrics; + + COMMENT ON TABLE deregistration.incidents_info IS 'Снятие с воинского учета. Инциденты (сверка данных от гражданина с ГИС ЕРВУ)'; + + CREATE INDEX IF NOT EXISTS idx_incidents_info_date ON deregistration.incidents_info (info_date); + CREATE INDEX IF NOT EXISTS idx_incidents_info_recr ON deregistration.incidents_info (recruitment_id); + CREATE INDEX IF NOT EXISTS idx_incidents_info_recr_date ON deregistration.incidents_info (recruitment_id, info_date); + + CREATE OR REPLACE VIEW deregistration.view_incidents_info AS + SELECT + incidents_info_id, + count_for_sign + count_signed AS count_all, + round(count_for_sign::numeric * 100 / (count_for_sign + count_signed)) AS percent_for_sign, + round(count_signed::numeric * 100 / (count_for_sign + count_signed)) AS percent_signed + FROM deregistration.incidents_info; + + + CREATE TABLE IF NOT EXISTS deregistration.active_applications + ( + active_applications_id bigserial NOT NULL PRIMARY KEY, + recruitment_id varchar(36) NOT NULL constraint fk_criminal_administrative_liability_recruitment_id references metrics.recruitment, + update_date timestamp without time zone NOT NULL DEFAULT now(), + info_date date NOT NULL, + count_active_applications bigint NOT NULL DEFAULT 0 + ) + WITH (OIDS = FALSE); + ALTER TABLE IF EXISTS deregistration.active_applications OWNER to ervu_business_metrics; + + COMMENT ON TABLE deregistration.active_applications IS 'Снятие с воинского учета. Активные заявления в ГИС ЕРВУ'; + + CREATE INDEX IF NOT EXISTS idx_active_applications_date ON deregistration.active_applications (info_date); + CREATE INDEX IF NOT EXISTS idx_active_applications_recr ON deregistration.active_applications (recruitment_id); + CREATE INDEX IF NOT EXISTS idx_active_applications_recr_date ON deregistration.active_applications (recruitment_id, info_date); + + + + + + add_incidents_change_address + + CREATE TABLE IF NOT EXISTS registration_change_address.incidents_epgu_info + ( + incidents_epgu_info_id bigserial NOT NULL PRIMARY KEY, + recruitment_id varchar(36) NOT NULL constraint fk_conv_info_records_from_easu_recruitment_id references metrics.recruitment, + update_date timestamp without time zone NOT NULL DEFAULT now(), + info_date date NOT NULL, + count_identify bigint NOT NULL DEFAULT 0, + count_registered bigint NOT NULL DEFAULT 0 + ) + WITH (OIDS = FALSE); + ALTER TABLE IF EXISTS registration_change_address.incidents_epgu_info OWNER to ervu_business_metrics; + + COMMENT ON TABLE registration_change_address.incidents_epgu_info IS 'Постановка на воинский учет при смене адреса. Инциденты ЕПГУ'; + + CREATE INDEX IF NOT EXISTS idx_incidents_epgu_info_date ON registration_change_address.incidents_epgu_info (info_date); + CREATE INDEX IF NOT EXISTS idx_incidents_epgu_info_recr ON registration_change_address.incidents_epgu_info (recruitment_id); + CREATE INDEX IF NOT EXISTS idx_incidents_epgu_info_recr_date ON registration_change_address.incidents_epgu_info (recruitment_id, info_date); + + CREATE OR REPLACE VIEW registration_change_address.view_incidents_epgu_info AS + SELECT + incidents_epgu_info_id, + round(count_registered::numeric * 100 / count_identify) AS percent_registered, + count_identify - count_registered AS count_not_identify + FROM registration_change_address.incidents_epgu_info; + + + + CREATE TABLE IF NOT EXISTS registration_change_address.incidents_info + ( + incidents_info_id bigserial NOT NULL PRIMARY KEY, + recruitment_id varchar(36) NOT NULL constraint fk_conv_info_records_from_easu_recruitment_id references metrics.recruitment, + update_date timestamp without time zone NOT NULL DEFAULT now(), + info_date date NOT NULL, + count_without_id_ern bigint NOT NULL DEFAULT 0, + count_discrepancy_epgu_info bigint NOT NULL DEFAULT 0 + ) + WITH (OIDS = FALSE); + ALTER TABLE IF EXISTS registration_change_address.incidents_info OWNER to ervu_business_metrics; + + COMMENT ON TABLE registration_change_address.incidents_info IS 'Постановка на воинский учет при смене адреса. Инциденты'; + + CREATE INDEX IF NOT EXISTS idx_incidents_info_date ON registration_change_address.incidents_info (info_date); + CREATE INDEX IF NOT EXISTS idx_incidents_info_recr ON registration_change_address.incidents_info (recruitment_id); + CREATE INDEX IF NOT EXISTS idx_incidents_info_recr_date ON registration_change_address.incidents_info (recruitment_id, info_date); + + CREATE OR REPLACE VIEW registration_change_address.view_incidents_info AS + SELECT + incidents_info_id, + count_without_id_ern + count_discrepancy_epgu_info AS count_all, + round(count_without_id_ern::numeric * 100 / (count_without_id_ern + count_discrepancy_epgu_info)) AS percent_without_id_ern, + round(count_discrepancy_epgu_info::numeric * 100 / (count_without_id_ern + count_discrepancy_epgu_info)) AS percent_discrepancy_epgu_info + FROM registration_change_address.incidents_info; + + DROP VIEW metrics.view_citizen_appeals; + CREATE OR REPLACE VIEW metrics.view_citizen_appeals AS + SELECT + citizen_appeals_id, + count_satisfided + count_not_satisfided + count_accepted_expired + count_accepted_on_time AS count_accepted_to_consideration, + count_submitted - (count_satisfided + count_not_satisfided + count_accepted_expired + count_accepted_on_time) AS count_submitted_difference_accepted, + round((count_satisfided + count_not_satisfided + count_accepted_expired + count_accepted_on_time)::numeric * 100 / count_submitted) AS percent_accepted_to_consideration, + round(count_satisfided::numeric * 100 / (count_satisfided + count_not_satisfided + count_accepted_expired + count_accepted_on_time)) AS percent_satisfided, + round(count_not_satisfided::numeric * 100 / (count_satisfided + count_not_satisfided + count_accepted_expired + count_accepted_on_time)) AS percent_not_satisfided, + round(count_accepted_expired::numeric * 100 / (count_satisfided + count_not_satisfided + count_accepted_expired + count_accepted_on_time)) AS percent_accepted_expired, + round(count_accepted_on_time::numeric * 100 / (count_satisfided + count_not_satisfided + count_accepted_expired + count_accepted_on_time)) AS percent_accepted_on_time + FROM metrics.citizen_appeals; + + + + +