Merge remote-tracking branch 'origin/develop' into ervu/tmp_makets
This commit is contained in:
commit
89bc5a6650
1 changed files with 373 additions and 1 deletions
|
|
@ -647,10 +647,382 @@
|
|||
round(count_criminal::numeric * 100 / (count_administrative + count_criminal)) AS percent_criminal,
|
||||
round(count_administrative::numeric * 100 / (count_administrative + count_criminal)) AS percent_administrative
|
||||
FROM metrics.criminal_administrative_liability;
|
||||
|
||||
|
||||
CREATE TABLE IF NOT EXISTS metrics.incidents_change_data_from_gir_vu
|
||||
(
|
||||
incidents_change_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_epgu_citizen_appeal bigint NOT NULL DEFAULT 0,
|
||||
count_manual bigint NOT NULL DEFAULT 0,
|
||||
count_send_to_gir_vu bigint NOT NULL DEFAULT 0,
|
||||
count_accepted bigint NOT NULL DEFAULT 0
|
||||
)
|
||||
WITH (OIDS = FALSE);
|
||||
ALTER TABLE IF EXISTS metrics.incidents_change_data_from_gir_vu OWNER to ervu_business_metrics;
|
||||
|
||||
COMMENT ON TABLE metrics.incidents_change_data_from_gir_vu IS 'Инциденты. Изменения сведений из ГИР ВУ';
|
||||
|
||||
CREATE INDEX IF NOT EXISTS idx_incidents_change_data_from_gir_vu_date ON metrics.incidents_change_data_from_gir_vu (info_date);
|
||||
CREATE INDEX IF NOT EXISTS idx_incidents_change_data_from_gir_vu_recr ON metrics.incidents_change_data_from_gir_vu (recruitment_id);
|
||||
CREATE INDEX IF NOT EXISTS idx_incidents_change_data_from_gir_vu_recr_date ON metrics.incidents_change_data_from_gir_vu (recruitment_id, info_date);
|
||||
|
||||
CREATE OR REPLACE VIEW metrics.view_incidents_change_data_from_gir_vu AS
|
||||
SELECT
|
||||
incidents_change_data_from_gir_vu_id,
|
||||
count_epgu_citizen_appeal + count_manual + count_send_to_gir_vu + count_accepted AS count_all,
|
||||
round(count_epgu_citizen_appeal::numeric * 100 / (count_epgu_citizen_appeal + count_manual + count_send_to_gir_vu + count_accepted)) AS percent_epgu_citizen_appeal,
|
||||
round(count_manual::numeric * 100 / (count_epgu_citizen_appeal + count_manual + count_send_to_gir_vu + count_accepted)) AS percent_manual,
|
||||
round(count_send_to_gir_vu::numeric * 100 / (count_epgu_citizen_appeal + count_manual + count_send_to_gir_vu + count_accepted)) AS percent_send_to_gir_vu,
|
||||
round(count_accepted::numeric * 100 / (count_epgu_citizen_appeal + count_manual + count_send_to_gir_vu + count_accepted)) AS percent_accepted
|
||||
FROM metrics.incidents_change_data_from_gir_vu;
|
||||
|
||||
|
||||
CREATE TABLE IF NOT EXISTS metrics.incidents_recieved_by_data_from_gir_vu
|
||||
(
|
||||
incidents_recieved_by_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_confirmed bigint NOT NULL DEFAULT 0,
|
||||
count_not_confirmed bigint NOT NULL DEFAULT 0
|
||||
)
|
||||
WITH (OIDS = FALSE);
|
||||
ALTER TABLE IF EXISTS metrics.incidents_recieved_by_data_from_gir_vu OWNER to ervu_business_metrics;
|
||||
|
||||
COMMENT ON TABLE metrics.incidents_recieved_by_data_from_gir_vu IS 'Инциденты. Принятые решения на основании данных из ГИР ВУ';
|
||||
|
||||
CREATE INDEX IF NOT EXISTS idx_incidents_recieved_by_data_from_gir_vu_date ON metrics.incidents_recieved_by_data_from_gir_vu (info_date);
|
||||
CREATE INDEX IF NOT EXISTS idx_incidents_recieved_by_data_from_gir_vu_recr ON metrics.incidents_recieved_by_data_from_gir_vu (recruitment_id);
|
||||
CREATE INDEX IF NOT EXISTS idx_incidents_recieved_by_data_from_gir_vu_recr_date ON metrics.incidents_recieved_by_data_from_gir_vu (recruitment_id, info_date);
|
||||
|
||||
CREATE OR REPLACE VIEW metrics.view_incidents_recieved_by_data_from_gir_vu AS
|
||||
SELECT
|
||||
incidents_recieved_by_data_from_gir_vu_id,
|
||||
count_confirmed + count_not_confirmed AS count_all,
|
||||
round(count_confirmed::numeric * 100 / (count_confirmed + count_not_confirmed)) AS percent_confirmed,
|
||||
round(count_not_confirmed::numeric * 100 / (count_confirmed + count_not_confirmed)) AS percent_not_confirmed
|
||||
FROM metrics.incidents_recieved_by_data_from_gir_vu;
|
||||
|
||||
|
||||
CREATE TABLE IF NOT EXISTS metrics.incidents_closed
|
||||
(
|
||||
incidents_closed_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_refused_to_archive bigint NOT NULL DEFAULT 0,
|
||||
count_accepted_to_archive bigint NOT NULL DEFAULT 0,
|
||||
count_auto_closed bigint NOT NULL DEFAULT 0,
|
||||
count_manual_closed bigint NOT NULL DEFAULT 0,
|
||||
count_returned bigint NOT NULL DEFAULT 0
|
||||
)
|
||||
WITH (OIDS = FALSE);
|
||||
ALTER TABLE IF EXISTS metrics.incidents_closed OWNER to ervu_business_metrics;
|
||||
|
||||
COMMENT ON TABLE metrics.incidents_closed IS 'Инциденты. Закрытые инциденты';
|
||||
|
||||
CREATE INDEX IF NOT EXISTS idx_incidents_closed_date ON metrics.incidents_closed (info_date);
|
||||
CREATE INDEX IF NOT EXISTS idx_incidents_closed_recr ON metrics.incidents_closed (recruitment_id);
|
||||
CREATE INDEX IF NOT EXISTS idx_incidents_closed_recr_date ON metrics.incidents_closed (recruitment_id, info_date);
|
||||
|
||||
CREATE OR REPLACE VIEW metrics.view_incidents_closed AS
|
||||
SELECT
|
||||
incidents_closed_id,
|
||||
count_refused_to_archive + count_accepted_to_archive + count_auto_closed + count_manual_closed + count_returned AS count_all,
|
||||
round(count_refused_to_archive::numeric * 100 / (count_refused_to_archive + count_accepted_to_archive + count_auto_closed + count_manual_closed + count_returned)) AS percent_refused_to_archive,
|
||||
round(count_accepted_to_archive::numeric * 100 / (count_refused_to_archive + count_accepted_to_archive + count_auto_closed + count_manual_closed + count_returned)) AS percent_accepted_to_archive,
|
||||
round(count_auto_closed::numeric * 100 / (count_refused_to_archive + count_accepted_to_archive + count_auto_closed + count_manual_closed + count_returned)) AS percent_auto_closed,
|
||||
round(count_manual_closed::numeric * 100 / (count_refused_to_archive + count_accepted_to_archive + count_auto_closed + count_manual_closed + count_returned)) AS percent_manual_closed,
|
||||
round(count_returned::numeric * 100 / (count_refused_to_archive + count_accepted_to_archive + count_auto_closed + count_manual_closed + count_returned)) AS percent_returned
|
||||
FROM metrics.incidents_closed;
|
||||
</sql>
|
||||
</changeSet>
|
||||
|
||||
<!-- <changeSet id="0005" author="akochetkov">-->
|
||||
<changeSet id="0005" author="ilyin">
|
||||
<comment>add table </comment>
|
||||
<sql>
|
||||
CREATE TABLE IF NOT EXISTS metrics.citizen_appeals
|
||||
(
|
||||
citizen_appeals_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_submitted bigint NOT NULL DEFAULT 0,
|
||||
count_satisfided bigint NOT NULL DEFAULT 0,
|
||||
count_not_satisfided bigint NOT NULL DEFAULT 0,
|
||||
count_accepted_expired bigint NOT NULL DEFAULT 0,
|
||||
count_accepted_on_time bigint NOT NULL DEFAULT 0
|
||||
)
|
||||
WITH (OIDS = FALSE);
|
||||
ALTER TABLE IF EXISTS metrics.citizen_appeals OWNER to ervu_business_metrics;
|
||||
|
||||
COMMENT ON TABLE metrics.citizen_appeals IS 'Обжалования. Обжалования граждан';
|
||||
|
||||
COMMENT ON COLUMN metrics.citizen_appeals.count_submitted IS 'Подано обращений';
|
||||
COMMENT ON COLUMN metrics.citizen_appeals.count_satisfided IS 'Удовлетворенных';
|
||||
COMMENT ON COLUMN metrics.citizen_appeals.count_not_satisfided IS 'Не удовлетворенных';
|
||||
COMMENT ON COLUMN metrics.citizen_appeals.count_accepted_expired IS 'Просроченных';
|
||||
COMMENT ON COLUMN metrics.citizen_appeals.count_accepted_on_time IS 'Принято в срок';
|
||||
|
||||
CREATE INDEX IF NOT EXISTS idx_citizen_appeals_date ON metrics.citizen_appeals (info_date);
|
||||
CREATE INDEX IF NOT EXISTS idx_citizen_appeals_recr ON metrics.citizen_appeals (recruitment_id);
|
||||
CREATE INDEX IF NOT EXISTS idx_citizen_appeals_recr_date ON metrics.citizen_appeals (recruitment_id, info_date);
|
||||
|
||||
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,
|
||||
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;
|
||||
|
||||
|
||||
|
||||
CREATE TABLE IF NOT EXISTS metrics.fz_53_appeals
|
||||
(
|
||||
fz_53_appeals_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_accepted bigint NOT NULL DEFAULT 0,
|
||||
count_refused bigint NOT NULL DEFAULT 0
|
||||
)
|
||||
WITH (OIDS = FALSE);
|
||||
ALTER TABLE IF EXISTS metrics.fz_53_appeals OWNER to ervu_business_metrics;
|
||||
|
||||
COMMENT ON TABLE metrics.fz_53_appeals IS 'Обжалования. Обжалования решений ФЗ-53';
|
||||
|
||||
COMMENT ON COLUMN metrics.fz_53_appeals.count_accepted IS 'Удовлетворенных жалоб';
|
||||
COMMENT ON COLUMN metrics.fz_53_appeals.count_refused IS 'Отклоненных жалоб';
|
||||
|
||||
CREATE INDEX IF NOT EXISTS idx_fz_53_appeals_date ON metrics.fz_53_appeals (info_date);
|
||||
CREATE INDEX IF NOT EXISTS idx_fz_53_appeals_recr ON metrics.fz_53_appeals (recruitment_id);
|
||||
CREATE INDEX IF NOT EXISTS idx_fz_53_appeals_recr_date ON metrics.fz_53_appeals (recruitment_id, info_date);
|
||||
|
||||
CREATE OR REPLACE VIEW metrics.view_fz_53_appeals AS
|
||||
SELECT
|
||||
fz_53_appeals_id,
|
||||
count_accepted + count_refused AS count_all,
|
||||
round(count_accepted::numeric * 100 / (count_accepted + count_refused)) AS percent_accepted,
|
||||
round(count_refused::numeric * 100 / (count_accepted + count_refused)) AS percent_refused
|
||||
FROM metrics.fz_53_appeals;
|
||||
|
||||
|
||||
CREATE TABLE IF NOT EXISTS metrics.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 metrics.active_applications OWNER to ervu_business_metrics;
|
||||
|
||||
COMMENT ON TABLE metrics.active_applications IS 'Обжалования. Активные заявления в ГИС ЕРВУ';
|
||||
|
||||
CREATE INDEX IF NOT EXISTS idx_active_applications_date ON metrics.active_applications (info_date);
|
||||
CREATE INDEX IF NOT EXISTS idx_active_applications_recr ON metrics.active_applications (recruitment_id);
|
||||
CREATE INDEX IF NOT EXISTS idx_active_applications_recr_date ON metrics.active_applications (recruitment_id, info_date);
|
||||
|
||||
|
||||
CREATE TABLE IF NOT EXISTS metrics.records_about_citizen
|
||||
(
|
||||
records_about_citizen_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_records_about_citizen bigint NOT NULL DEFAULT 0
|
||||
)
|
||||
WITH (OIDS = FALSE);
|
||||
ALTER TABLE IF EXISTS metrics.records_about_citizen OWNER to ervu_business_metrics;
|
||||
|
||||
COMMENT ON TABLE metrics.records_about_citizen IS 'Обжалования. Записи о гражданах, обновленных в ГИС ЕРВУ';
|
||||
|
||||
CREATE INDEX IF NOT EXISTS idx_records_about_citizen_date ON metrics.records_about_citizen (info_date);
|
||||
CREATE INDEX IF NOT EXISTS idx_records_about_citizen_recr ON metrics.records_about_citizen (recruitment_id);
|
||||
CREATE INDEX IF NOT EXISTS idx_records_about_citizen_recr_date ON metrics.records_about_citizen (recruitment_id, info_date);
|
||||
|
||||
|
||||
|
||||
ALTER TABLE metrics.convert_info_records_from_easu ADD COLUMN IF NOT EXISTS count_all bigint NOT NULL DEFAULT 0;
|
||||
|
||||
DROP VIEW IF EXISTS metrics.view_convert_info_records_from_easu;
|
||||
CREATE OR REPLACE VIEW metrics.view_convert_info_records_from_easu AS
|
||||
SELECT
|
||||
convert_info_records_from_easu_id,
|
||||
round(count_unique::numeric * 100 / count_all) AS percent_unique,
|
||||
round(count_flk_and_duplicate::numeric * 100 / count_all) AS percent_flk_and_duplicate,
|
||||
count_all - count_unique AS count_without_unique,
|
||||
count_all - count_flk_and_duplicate AS count_without_flk_and_duplicate
|
||||
FROM metrics.convert_info_records_from_easu;
|
||||
</sql>
|
||||
</changeSet>
|
||||
|
||||
<changeSet id="0006" author="ilyin">
|
||||
<comment>create schema summonses_list_subsystem</comment>
|
||||
<sql>
|
||||
|
||||
CREATE SCHEMA IF NOT EXISTS summonses_list_subsystem;
|
||||
|
||||
CREATE TABLE IF NOT EXISTS summonses_list_subsystem.personal_accounts
|
||||
(
|
||||
personal_accounts_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_registered bigint NOT NULL DEFAULT 0,
|
||||
count_not_registered bigint NOT NULL DEFAULT 0
|
||||
)
|
||||
WITH (OIDS = FALSE);
|
||||
ALTER TABLE IF EXISTS summonses_list_subsystem.personal_accounts OWNER to ervu_business_metrics;
|
||||
|
||||
COMMENT ON TABLE summonses_list_subsystem.personal_accounts IS 'Реестр повесток подсистема. Личные кабинеты';
|
||||
|
||||
CREATE INDEX IF NOT EXISTS idx_personal_accounts_date ON summonses_list_subsystem.personal_accounts (info_date);
|
||||
CREATE INDEX IF NOT EXISTS idx_personal_accounts_recr ON summonses_list_subsystem.personal_accounts (recruitment_id);
|
||||
CREATE INDEX IF NOT EXISTS idx_personal_accounts_recr_date ON summonses_list_subsystem.personal_accounts (recruitment_id, info_date);
|
||||
|
||||
COMMENT ON COLUMN summonses_list_subsystem.personal_accounts.count_registered IS 'Состоящих на учете';
|
||||
COMMENT ON COLUMN summonses_list_subsystem.personal_accounts.count_not_registered IS 'Не состоящих на учете';
|
||||
|
||||
CREATE OR REPLACE VIEW summonses_list_subsystem.view_personal_accounts AS
|
||||
SELECT
|
||||
personal_accounts_id,
|
||||
count_registered + count_not_registered AS count_all,
|
||||
round(count_registered::numeric * 100 / (count_registered + count_not_registered)) AS percent_registered,
|
||||
round(count_not_registered::numeric * 100 / (count_registered + count_not_registered)) AS percent_not_registered
|
||||
FROM summonses_list_subsystem.personal_accounts;
|
||||
|
||||
|
||||
CREATE TABLE IF NOT EXISTS summonses_list_subsystem.summonses_direct_to_pers_acc
|
||||
(
|
||||
summonses_direct_to_pers_acc_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_draft_board bigint NOT NULL DEFAULT 0,
|
||||
count_place_of_military_service bigint NOT NULL DEFAULT 0,
|
||||
count_med_inspection bigint NOT NULL DEFAULT 0,
|
||||
count_doc_clarification bigint NOT NULL DEFAULT 0
|
||||
)
|
||||
WITH (OIDS = FALSE);
|
||||
ALTER TABLE IF EXISTS summonses_list_subsystem.summonses_direct_to_pers_acc OWNER to ervu_business_metrics;
|
||||
|
||||
COMMENT ON TABLE summonses_list_subsystem.summonses_direct_to_pers_acc IS 'Реестр повесток подсистема. Направление повесток в ЛК РП';
|
||||
|
||||
CREATE INDEX IF NOT EXISTS idx_summonses_direct_to_pers_acc_date ON summonses_list_subsystem.summonses_direct_to_pers_acc (info_date);
|
||||
CREATE INDEX IF NOT EXISTS idx_summonses_direct_to_pers_acc_recr ON summonses_list_subsystem.summonses_direct_to_pers_acc (recruitment_id);
|
||||
CREATE INDEX IF NOT EXISTS idx_summonses_direct_to_pers_acc_recr_date ON summonses_list_subsystem.summonses_direct_to_pers_acc (recruitment_id, info_date);
|
||||
|
||||
COMMENT ON COLUMN summonses_list_subsystem.summonses_direct_to_pers_acc.count_draft_board IS 'Для прохождения призывной комиссии';
|
||||
COMMENT ON COLUMN summonses_list_subsystem.summonses_direct_to_pers_acc.count_place_of_military_service IS 'Для отправки к месту службы';
|
||||
COMMENT ON COLUMN summonses_list_subsystem.summonses_direct_to_pers_acc.count_med_inspection IS 'Для медосвидетельствования';
|
||||
COMMENT ON COLUMN summonses_list_subsystem.summonses_direct_to_pers_acc.count_doc_clarification IS 'Для уточнения документов ВУ';
|
||||
|
||||
CREATE OR REPLACE VIEW summonses_list_subsystem.view_summonses_direct_to_pers_acc AS
|
||||
SELECT
|
||||
summonses_direct_to_pers_acc_id,
|
||||
count_draft_board + count_place_of_military_service + count_med_inspection + count_doc_clarification AS count_all,
|
||||
round(count_draft_board::numeric * 100 / (count_draft_board + count_place_of_military_service + count_med_inspection + count_doc_clarification)) AS percent_draft_board,
|
||||
round(count_place_of_military_service::numeric * 100 / (count_draft_board + count_place_of_military_service + count_med_inspection + count_doc_clarification)) AS percent_place_of_military_service,
|
||||
round(count_med_inspection::numeric * 100 / (count_draft_board + count_place_of_military_service + count_med_inspection + count_doc_clarification)) AS percent_med_inspection,
|
||||
round(count_doc_clarification::numeric * 100 / (count_draft_board + count_place_of_military_service + count_med_inspection + count_doc_clarification)) AS percent_doc_clarification
|
||||
FROM summonses_list_subsystem.summonses_direct_to_pers_acc;
|
||||
|
||||
|
||||
CREATE TABLE IF NOT EXISTS summonses_list_subsystem.summonses_list
|
||||
(
|
||||
summonses_list_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,
|
||||
summonse_type character varying NOT NULL,
|
||||
count_view_arrived bigint NOT NULL DEFAULT 0,
|
||||
count_not_view_arrived bigint NOT NULL DEFAULT 0,
|
||||
count_view_less_20_days bigint NOT NULL DEFAULT 0,
|
||||
count_not_view_less_20_days bigint NOT NULL DEFAULT 0,
|
||||
count_view_greater_20_days bigint NOT NULL DEFAULT 0,
|
||||
count_not_view_greater_20_days bigint NOT NULL DEFAULT 0
|
||||
)
|
||||
WITH (OIDS = FALSE);
|
||||
ALTER TABLE IF EXISTS summonses_list_subsystem.summonses_list OWNER to ervu_business_metrics;
|
||||
|
||||
COMMENT ON TABLE summonses_list_subsystem.summonses_list IS 'Реестр повесток подсистема. Для прохождения призывной комиссии';
|
||||
|
||||
CREATE INDEX IF NOT EXISTS idx_summonses_list_date ON summonses_list_subsystem.summonses_list (info_date);
|
||||
CREATE INDEX IF NOT EXISTS idx_summonses_list_recr ON summonses_list_subsystem.summonses_list (recruitment_id);
|
||||
CREATE INDEX IF NOT EXISTS idx_summonses_list_recr_date ON summonses_list_subsystem.summonses_list (recruitment_id, info_date);
|
||||
|
||||
COMMENT ON COLUMN summonses_list_subsystem.summonses_list.summonse_type IS 'Тип повестки (DRAFT_BOARD = призывная комиссия; MILITARY_SERVICE = отправка к месту службы; MED_INSPECTION = медосвидетельствование; DOC_CLARIFICATION = уточнение документов; NOT_REGISTERED = не состоит на учете)';
|
||||
COMMENT ON COLUMN summonses_list_subsystem.summonses_list.count_view_arrived IS 'Гражданин явился, просмотрено';
|
||||
COMMENT ON COLUMN summonses_list_subsystem.summonses_list.count_not_view_arrived IS 'Гражданин явился, не просмотрено';
|
||||
COMMENT ON COLUMN summonses_list_subsystem.summonses_list.count_view_less_20_days IS 'Менее 20 дней, просмотрено';
|
||||
COMMENT ON COLUMN summonses_list_subsystem.summonses_list.count_not_view_less_20_days IS 'Менее 20 дней, не просмотрено';
|
||||
COMMENT ON COLUMN summonses_list_subsystem.summonses_list.count_view_greater_20_days IS 'Более 20 дней, просмотрено';
|
||||
COMMENT ON COLUMN summonses_list_subsystem.summonses_list.count_not_view_greater_20_days IS 'Более 20 дней, не просмотрено';
|
||||
|
||||
CREATE OR REPLACE VIEW summonses_list_subsystem.view_summonses_list AS
|
||||
SELECT
|
||||
summonses_list_id,
|
||||
count_view_arrived + count_not_view_arrived AS count_arrived_all,
|
||||
round(count_view_arrived::numeric * 100 / (count_view_arrived + count_not_view_arrived)) AS percent_view_arrived,
|
||||
round(count_not_view_arrived::numeric * 100 / (count_view_arrived + count_not_view_arrived)) AS percent_not_view_arrived,
|
||||
count_view_less_20_days + count_not_view_less_20_days AS count_less_20_days_all,
|
||||
round(count_view_less_20_days::numeric * 100 / (count_view_less_20_days + count_not_view_less_20_days)) AS percent_view_less_20_days,
|
||||
round(count_not_view_less_20_days::numeric * 100 / (count_view_less_20_days + count_not_view_less_20_days)) AS percent_not_view_less_20_days,
|
||||
count_view_greater_20_days + count_not_view_greater_20_days AS count_greater_20_days_all,
|
||||
round(count_view_greater_20_days::numeric * 100 / (count_view_greater_20_days + count_not_view_greater_20_days)) AS percent_view_greater_20_days,
|
||||
round(count_not_view_greater_20_days::numeric * 100 / (count_view_greater_20_days + count_not_view_greater_20_days)) AS percent_not_view_greater_20_days
|
||||
FROM summonses_list_subsystem.summonses_list;
|
||||
|
||||
|
||||
CREATE TABLE IF NOT EXISTS summonses_list_subsystem.requests_direct_to_pers_acc
|
||||
(
|
||||
requests_direct_to_pers_acc_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_registered bigint NOT NULL DEFAULT 0,
|
||||
count_registered_formed bigint NOT NULL DEFAULT 0,
|
||||
count_not_registered bigint NOT NULL DEFAULT 0,
|
||||
count_not_registered_formed bigint NOT NULL DEFAULT 0
|
||||
)
|
||||
WITH (OIDS = FALSE);
|
||||
ALTER TABLE IF EXISTS summonses_list_subsystem.requests_direct_to_pers_acc OWNER to ervu_business_metrics;
|
||||
|
||||
COMMENT ON TABLE summonses_list_subsystem.requests_direct_to_pers_acc IS 'Реестр повесток подсистема. Направление запросов в ЛК РП для выписки';
|
||||
|
||||
CREATE INDEX IF NOT EXISTS idx_requests_direct_to_pers_acc_date ON summonses_list_subsystem.requests_direct_to_pers_acc (info_date);
|
||||
CREATE INDEX IF NOT EXISTS idx_requests_direct_to_pers_acc_recr ON summonses_list_subsystem.requests_direct_to_pers_acc (recruitment_id);
|
||||
CREATE INDEX IF NOT EXISTS idx_requests_direct_to_pers_acc_recr_date ON summonses_list_subsystem.requests_direct_to_pers_acc (recruitment_id, info_date);
|
||||
|
||||
COMMENT ON COLUMN summonses_list_subsystem.requests_direct_to_pers_acc.count_registered IS 'состоящие на ВУ';
|
||||
COMMENT ON COLUMN summonses_list_subsystem.requests_direct_to_pers_acc.count_registered_formed IS 'сформировано для состоящих на ВУ';
|
||||
COMMENT ON COLUMN summonses_list_subsystem.requests_direct_to_pers_acc.count_not_registered IS 'не состоящие на ВУ';
|
||||
COMMENT ON COLUMN summonses_list_subsystem.requests_direct_to_pers_acc.count_not_registered_formed IS 'сформировано для не состоящих на ВУ';
|
||||
|
||||
CREATE OR REPLACE VIEW summonses_list_subsystem.view_requests_direct_to_pers_acc AS
|
||||
SELECT
|
||||
requests_direct_to_pers_acc_id,
|
||||
count_registered + count_not_registered AS count_all,
|
||||
round(count_registered::numeric * 100 / (count_registered + count_not_registered)) AS percent_registered,
|
||||
round(count_not_registered::numeric * 100 / (count_registered + count_not_registered)) AS percent_not_registered,
|
||||
round(count_registered_formed::numeric * 100 / count_registered) AS percent_registered_formed,
|
||||
round(count_not_registered_formed::numeric * 100 / count_not_registered) AS percent_not_registered_formed
|
||||
FROM summonses_list_subsystem.requests_direct_to_pers_acc;
|
||||
|
||||
|
||||
</sql>
|
||||
</changeSet>
|
||||
|
||||
<!-- <changeSet id="0007" author="ilyin">-->
|
||||
<!-- <comment>add table </comment>-->
|
||||
<!-- <sql>-->
|
||||
|
||||
|
|
|
|||
Loading…
Add table
Add a link
Reference in a new issue