ERVU-168_db_incidents
This commit is contained in:
parent
fb7e7b1240
commit
409755bc89
1 changed files with 91 additions and 0 deletions
|
|
@ -647,6 +647,97 @@
|
|||
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>
|
||||
|
||||
|
|
|
|||
Loading…
Add table
Add a link
Reference in a new issue