return: text lang: plpgsql parameters: p0: type: text name: i_schema p1: type: bigint name: i_import_id src: | BEGIN RAISE NOTICE '% | SCHEMA : %', to_char(CURRENT_TIMESTAMP, 'YYYY-MM-DD HH24:MI:ss'), i_schema; RAISE NOTICE '% | IMPORT n° : %', to_char(CURRENT_TIMESTAMP, 'YYYY-MM-DD HH24:MI:ss'), i_import_id; RAISE NOTICE '% | CREATION DES TABLES DE TRAVAIL', to_char(CURRENT_TIMESTAMP, 'YYYY-MM-DD HH24:MI:ss'); DROP TABLE IF EXISTS w_mat_rss; DROP TABLE IF EXISTS w_mat_rss_work; DROP TABLE IF EXISTS w_mat_actes; DROP TABLE IF EXISTS w_mat_diagnostics; DROP TABLE IF EXISTS w_mat_acte_accouchement; DROP TABLE IF EXISTS w_mat_accouchement_hors_img; -- création des tables de travail EXECUTE FORMAT (' CREATE TEMP TABLE w_mat_rss_work AS SELECT oid as rss_id, ghm_id, confirmation_codage, age_gestationnel, date_dernieres_regles FROM %I.p_rss WHERE p_rss.import_id = %s ', i_schema, i_import_id); EXECUTE FORMAT (' CREATE TEMP TABLE w_mat_rss AS SELECT * FROM %I.p_rss_maternite LIMIT 0 ', i_schema); EXECUTE FORMAT (' CREATE TEMP TABLE w_mat_actes AS SELECT p_rss_actes.rss_id, p_rss_actes.acte_id, p_rss_actes.activite_ccam, p_rss_actes.date_acte FROM %I.p_rss_actes JOIN w_mat_rss_work ON w_mat_rss_work.rss_id = p_rss_actes.rss_id ', i_schema); EXECUTE FORMAT (' CREATE TEMP TABLE w_mat_diagnostics AS SELECT p_rss_diagnostics.rss_id, p_rss_diagnostics.type_diagnostic, t_diagnostics.code as diagnostic_code FROM %I.p_rss_diagnostics JOIN pmsi.t_diagnostics ON t_diagnostics.oid = p_rss_diagnostics.diagnostic_id JOIN w_mat_rss_work ON w_mat_rss_work.rss_id = p_rss_diagnostics.rss_id ', i_schema); -- séjours avec accouchement RAISE NOTICE '% | SEJOURS AVEC ACCOUCHEMENT', to_char(CURRENT_TIMESTAMP, 'YYYY-MM-DD HH24:MI:ss'); CREATE TEMP TABLE w_mat_acte_accouchement AS SELECT DISTINCT w_mat_actes.rss_id FROM w_mat_actes JOIN pmsi.v_listes_contenu_1 ON v_listes_contenu_1.to_id = w_mat_actes.acte_id WHERE v_listes_contenu_1.liste_code = 'CTI_LT_A323_2015'; -- sejours d'accouchement hors IMG RAISE NOTICE '% | ACCOUCHEMENTS HORS IMG', to_char(CURRENT_TIMESTAMP, 'YYYY-MM-DD HH24:MI:ss'); CREATE TEMP TABLE w_mat_accouchement_hors_img AS SELECT DISTINCT w_mat_diagnostics.rss_id FROM w_mat_diagnostics WHERE 1=1 AND w_mat_diagnostics.type_diagnostic = 'DA' AND w_mat_diagnostics.diagnostic_code like 'Z37%' AND substring(w_mat_diagnostics.diagnostic_code FROM 5 FOR 1) != 1; INSERT INTO w_mat_rss (rss_id) SELECT w_mat_accouchement_hors_img.rss_id FROM w_mat_accouchement_hors_img UNION SELECT w_mat_acte_accouchement.rss_id FROM w_mat_acte_accouchement; UPDATE w_mat_rss SET accouchement_hors_img = 1 FROM w_mat_accouchement_hors_img WHERE 1=1 AND w_mat_accouchement_hors_img.rss_id = w_mat_rss.rss_id AND accouchement_hors_img IS DISTINCT FROM 1; UPDATE w_mat_rss SET avec_acte_accouchement = 1 FROM w_mat_acte_accouchement WHERE 1=1 AND w_mat_acte_accouchement.rss_id = w_mat_rss.rss_id AND avec_acte_accouchement IS DISTINCT FROM 1; -- accouchements hors CMD 14 RAISE NOTICE '% | ACCOUCHEMENTS HORS CMD14', to_char(CURRENT_TIMESTAMP, 'YYYY-MM-DD HH24:MI:ss'); UPDATE w_mat_rss SET hors_cmd_14 = 1 FROM w_mat_rss_work JOIN pmsi.t_ghm ON t_ghm.oid = w_mat_rss_work.ghm_id JOIN pmsi.t_cmd ON t_cmd.oid = t_ghm.cmd_id WHERE 1=1 AND w_mat_rss_work.rss_id = w_mat_rss.rss_id AND t_cmd.code NOT IN ('14', '01', '08'); -- Confirmation codage (NULL, blanc: non renseigné 1:oui 2:non) RAISE NOTICE '% | CONFIRMATION DE CODAGE', to_char(CURRENT_TIMESTAMP, 'YYYY-MM-DD HH24:MI:ss'); UPDATE w_mat_rss SET confirmation_codage = w_mat_rss_work.confirmation_codage FROM w_mat_rss_work WHERE 1=1 AND w_mat_rss_work.rss_id = w_mat_rss.rss_id AND w_mat_rss.hors_cmd_14 = 1; -- Age gestationnel manquant RAISE NOTICE '% | AGE GESTATIONNEL MANQUANT', to_char(CURRENT_TIMESTAMP, 'YYYY-MM-DD HH24:MI:ss'); UPDATE w_mat_rss SET age_gestationnel_manquant = CASE WHEN w_mat_rss_work.age_gestationnel = 0 THEN 1 ELSE 0 END, age_gestationnel_inf_22sa = CASE WHEN w_mat_rss_work.age_gestationnel < 22 THEN 1 ELSE 0 END FROM w_mat_rss_work WHERE w_mat_rss_work.rss_id = w_mat_rss.rss_id; -- Accouchement hors etablissement RAISE NOTICE '% | ACCOUCHEMENT HORS ETABLISSEMENT', to_char(CURRENT_TIMESTAMP, 'YYYY-MM-DD HH24:MI:ss'); WITH w_hors_etablissement AS ( SELECT DISTINCT w_mat_diagnostics.rss_id FROM w_mat_rss JOIN w_mat_diagnostics ON w_mat_diagnostics.rss_id = w_mat_rss.rss_id WHERE 1=1 AND w_mat_diagnostics.type_diagnostic = 'DP' AND w_mat_diagnostics.diagnostic_code = 'Z3900' ) UPDATE w_mat_rss SET hors_etablissement = 1 FROM w_hors_etablissement WHERE 1=1 AND w_hors_etablissement.rss_id = w_mat_rss.rss_id AND w_mat_rss.hors_etablissement IS DISTINCT FROM 1; -- Calcul de l'écart de calcul de l'age gestationnel -- d'apres la methode du tableau 1.Q.8.SACC du guide de lecture OVALIDE exDG 2018 -- -- w_date_accouchement calcule par RSS la première date d'accouchement -- d'après les actes hors anesthésie de la liste d'actes d'accouchement -- -- w_ecart age_gestationnel calcule l'écart entre la date d'accouchement et la date de dernières regles -- en nombre de semaines écoulées (7 semaines et 6 jours = 7 semaines) -- Si l'écart n'est pas calculable, il vaut -1 -- Si l'écart est supérieur à 2, il vaut 3 -- Si la date d'accouchement, l'age gestationnel ou la date des dernieres regles sont absents, il vaut -1 RAISE NOTICE '% | ECART DE CALCUL DE L''AGE GESTATIONNEL', to_char(CURRENT_TIMESTAMP, 'YYYY-MM-DD HH24:MI:ss'); WITH w_date_accouchement AS ( SELECT w_mat_rss.rss_id , min(date_acte) as date_accouchement FROM w_mat_rss JOIN w_mat_actes ON w_mat_actes.rss_id = w_mat_rss.rss_id JOIN pmsi.v_listes_contenu_1 ON v_listes_contenu_1.to_id = w_mat_actes.acte_id WHERE 1=1 AND v_listes_contenu_1.liste_code = 'CTI_LT_A323_2015' AND w_mat_actes.activite_ccam != '4' GROUP BY 1 ), w_ecart_age_gestationnel AS ( SELECT w_mat_rss.rss_id , w_date_accouchement.date_accouchement , LEAST(COALESCE(abs((w_date_accouchement.date_accouchement - w_mat_rss_work.date_dernieres_regles) / 7 - w_mat_rss_work.age_gestationnel), -1), 3) as ecart FROM w_mat_rss JOIN w_mat_rss_work ON w_mat_rss_work.rss_id = w_mat_rss.rss_id LEFT JOIN w_date_accouchement ON w_date_accouchement.rss_id = w_mat_rss.rss_id ) UPDATE w_mat_rss SET ecart_age_gestationnel = CASE WHEN w_ecart_age_gestationnel.date_accouchement IS NULL OR w_mat_rss_work.age_gestationnel = 0 OR w_mat_rss_work.date_dernieres_regles = '2099-12-31'::date THEN -1 ELSE w_ecart_age_gestationnel.ecart END FROM w_ecart_age_gestationnel JOIN w_mat_rss_work ON w_mat_rss_work.rss_id = w_ecart_age_gestationnel.rss_id WHERE 1=1 AND w_ecart_age_gestationnel.rss_id = w_mat_rss.rss_id AND w_mat_rss.ecart_age_gestationnel IS DISTINCT FROM w_ecart_age_gestationnel.ecart; --suppresion des anciennes générations RAISE NOTICE '% | SUPPRESION DES ANCIENNES GENERATIONS', to_char(CURRENT_TIMESTAMP, 'YYYY-MM-DD HH24:MI:ss'); EXECUTE FORMAT (' DELETE FROM %I.p_rss_maternite USING w_mat_rss_work WHERE p_rss_maternite.rss_id = w_mat_rss_work.rss_id ', i_schema); -- ajoute des données RAISE NOTICE '% | AJOUTE DES DONNEES', to_char(CURRENT_TIMESTAMP, 'YYYY-MM-DD HH24:MI:ss'); EXECUTE FORMAT (' INSERT INTO %I.p_rss_maternite ( rss_id, accouchement_hors_img, age_gestationnel_manquant, age_gestationnel_inf_22sa, avec_acte_accouchement, confirmation_codage, ecart_age_gestationnel, hors_cmd_14, hors_etablissement ) SELECT rss_id, COALESCE(accouchement_hors_img, 0), COALESCE(age_gestationnel_manquant, 0), COALESCE(age_gestationnel_inf_22sa, 0), COALESCE(avec_acte_accouchement, 0), COALESCE(confirmation_codage, ''''), COALESCE(ecart_age_gestationnel, 0), COALESCE(hors_cmd_14, 0), COALESCE(hors_etablissement, 0) FROM w_mat_rss ', i_schema); DROP TABLE w_mat_rss; DROP TABLE w_mat_rss_work; DROP TABLE w_mat_actes; DROP TABLE w_mat_diagnostics; DROP TABLE w_mat_acte_accouchement; DROP TABLE w_mat_accouchement_hors_img; RETURN 'OK'; END;