return: text lang: plpgsql src: | DECLARE result TEXT; _module_pmsimco TEXT; BEGIN RAISE NOTICE '%' , 'Initialisation filiere'; -- Contenu table INSERT INTO activite.t_filiere_soin (oid, code, texte, texte_court) SELECT 0, '**', 'Non renseignée', 'Non renseignée' WHERE 0 NOT IN (SELECT oid FROM activite.t_filiere_soin); IF (SELECT count(*) FROM activite.t_filiere_soin WHERE oid > 0) = 0 THEN RETURN 'OK. Aucune filiere'; END IF; RAISE NOTICE '%' , 'Application des regles'; -- pmsi mco ? IF EXISTS (SELECT * FROM pg_tables WHERE schemaname = 'pmsi' AND tablename = 'p_rss') THEN _module_pmsimco = '1'; RAISE NOTICE '%' , 'Application des regles. Avec PMSI MCO'; ELSE _module_pmsimco = '0'; END IF; -- Sejours et RSS à Traiter RAISE NOTICE '%' , 'Application des regles. Identification des sejours'; DROP SEQUENCE IF EXISTS w_sejours_rss_sequence; CREATE SEQUENCE w_sejours_rss_sequence; DROP TABLE IF EXISTS w_sejours_rss; IF _module_pmsimco = '1' THEN -- si pmsi mco CREATE TEMP TABLE w_sejours_rss AS SELECT nextval('w_sejours_rss_sequence'::regclass) AS oid, COALESCE(t_finess.oid,0) AS finess_id, p_sejours.oid AS sejour_id, p_sejours.no_sejour AS no_sejour, COALESCE(p_rss.oid,0) AS rss_id, diagnostic_principal_id, diagnostic_relie_id, NULL::bigint[] AS diagnostic_associe_liste_rule_id, NULL::bigint[] AS acte_liste_rule_id, NULL::bigint[] AS prestation_liste_rule_id, NULL::bigint[] AS rubrique_liste_rule_id, p_rss.ghm_id AS ghm_pmsi_id, p_sejours.ghm_id AS ghm_activite_id, COALESCE(medecin_rss_id,0) AS medecin_rss_id, medecin_sejour_id, COALESCE(t_medecins_base.specialite_id,0) AS specialite_sejour_id, p_sejours.type_sejour, t_lieux.unite_fonctionnelle_id, t_lieux.service_facturation_id, t_lits.etage_id, t_lieux.unite_fonctionnelle_id AS unite_fonctionnelle_entree_id, t_lieux.service_facturation_id AS service_facturation_entree_id, t_lits.etage_id AS etage_entree_id, t_lieux.activite_id, 0::bigint AS filiere_soin_id, 0::bigint AS filiere_soin_priorite FROM activite.p_sejours JOIN activite.t_lieux ON lieu_sortie_id = t_lieux.oid JOIN activite.t_lits ON t_lieux.lit_id = t_lits.oid LEFT JOIN pmsi.p_rss ON no_sejour_administratif = no_sejour AND p_sejours.date_sortie = p_rss.date_sortie AND p_rss.etat = '' LEFT JOIN pmsi.t_medecins t_medecins_pmsi ON medecin_rss_id = t_medecins_pmsi.oid LEFT JOIN activite.t_medecins_administratifs ON medecin_sejour_id = t_medecins_administratifs.oid LEFT JOIN base.t_medecins t_medecins_base ON t_medecins_administratifs.medecin_id = t_medecins_base.oid LEFT JOIN base.t_finess ON p_sejours.finess = t_finess.code ; INSERT INTO w_sejours_rss SELECT nextval('w_sejours_rss_sequence'::regclass) AS oid, COALESCE(t_finess.oid,0) AS finess_id, 0 AS sejour_id, '' AS no_sejour, p_rss.oid AS rss_id, diagnostic_principal_id, diagnostic_relie_id, NULL::bigint[] AS diagnostic_associe_liste_rule_id, NULL::bigint[] AS acte_liste_rule_id, NULL::bigint[] AS prestation_liste_rule_id, NULL::bigint[] AS rubrique_liste_rule_id, p_rss.ghm_id AS ghm_pmsi_id, 0 AS ghm_activite_id, medecin_rss_id, 0::bigint AS medecin_sejour_id, COALESCE(t_medecins_base.specialite_id,0) AS specialite_sejour_id, ''::text AS type_sejour, 0::bigint AS unite_fonctionnelle_id, 0::bigint AS service_facturation_id, 0::bigint AS etage_id, 0::bigint AS unite_fonctionnelle_entree_id, 0::bigint AS service_facturation_entree_id, 0::bigint AS etage_entree_id, 0::bigint AS activite_id, 0::bigint AS filiere_soin_id, 0::bigint AS filiere_soin_priorite FROM pmsi.p_rss LEFT JOIN pmsi.t_medecins t_medecins_pmsi ON medecin_rss_id = t_medecins_pmsi.oid LEFT JOIN base.t_medecins t_medecins_base ON t_medecins_pmsi.medecin_id = t_medecins_base.oid LEFT JOIN base.t_finess ON p_rss.finess = t_finess.code WHERE p_rss.oid NOT IN (SELECT rss_id FROM w_sejours_rss); ELSE -- si pas pmsi mco CREATE TEMP TABLE w_sejours_rss AS SELECT nextval('w_sejours_rss_sequence'::regclass) AS oid, COALESCE(t_finess.oid,0) AS finess_id, p_sejours.oid AS sejour_id, p_sejours.no_sejour AS no_sejour, 0 AS rss_id, 0::bigint AS diagnostic_principal_id, 0::bigint AS diagnostic_relie_id, NULL::bigint[] AS diagnostic_associe_liste_rule_id, NULL::bigint[] AS acte_liste_rule_id, NULL::bigint[] AS prestation_liste_rule_id, NULL::bigint[] AS rubrique_liste_rule_id, 0::bigint AS ghm_pmsi_id, p_sejours.ghm_id AS ghm_activite_id, 0 AS medecin_rss_id, medecin_sejour_id, COALESCE(t_medecins_base.specialite_id,0) AS specialite_sejour_id, p_sejours.type_sejour, t_lieux.unite_fonctionnelle_id, t_lieux.service_facturation_id, t_lits.etage_id, t_lieux.unite_fonctionnelle_id AS unite_fonctionnelle_entree_id, t_lieux.service_facturation_id AS service_facturation_entree_id, t_lits.etage_id AS etage_entree_id, t_lieux.activite_id, 0::bigint AS filiere_soin_id, 0::bigint AS filiere_soin_priorite FROM activite.p_sejours JOIN activite.t_lieux ON lieu_sortie_id = t_lieux.oid JOIN activite.t_lits ON t_lieux.lit_id = t_lits.oid LEFT JOIN base.t_finess ON p_sejours.finess = t_finess.code LEFT JOIN activite.t_medecins_administratifs ON medecin_sejour_id = t_medecins_administratifs.oid LEFT JOIN base.t_medecins t_medecins_base ON t_medecins_administratifs.medecin_id = t_medecins_base.oid; END IF; -- Unites d'entrées UPDATE w_sejours_rss SET unite_fonctionnelle_entree_id = t_lieux.unite_fonctionnelle_id, service_facturation_entree_id = t_lieux.service_facturation_id, etage_entree_id = t_lits.etage_id FROM activite.p_mouvements_sejour JOIN activite.t_lieux ON p_mouvements_sejour.lieu_id = t_lieux.oid JOIN activite.t_lits ON t_lieux.lit_id = t_lits.oid WHERE w_sejours_rss.no_sejour = p_mouvements_sejour.no_sejour AND nb_entrees_directes = 1 AND ( t_lieux.unite_fonctionnelle_id <> unite_fonctionnelle_entree_id OR t_lieux.service_facturation_id <> service_facturation_entree_id OR t_lits.etage_id <> etage_entree_id ) ; -- GHM sur services non MCO -- Verrouillé pour l'instant (on verra par la suite) -- UPDATE w_sejours_rss SET -- ghm_pmsi_id = 0, -- ghm_activite_id = 0 -- FROM activite.t_services_facturation -- WHERE service_facturation_id = t_services_facturation .oid AND -- type_t2a <> '1' AND -- service_facturation_id <> 0 AND -- (ghm_pmsi_id > 0 OR -- ghm_activite_id > 0) -- ; -- UPDATE w_sejours_rss SET medecin_rss_id = 0 WHERE medecin_sejour_id <> 0; UPDATE w_sejours_rss SET finess_id = (SELECT MAX(finess_id) FROM w_sejours_rss WHERE finess_id <> 0) WHERE finess_id = 0 AND (SELECT MAX(finess_id) FROM w_sejours_rss WHERE finess_id <> 0) <> 0; UPDATE w_sejours_rss SET finess_id = (SELECT MAX(oid) FROM base.t_finess) WHERE finess_id = 0; CREATE INDEX w_sejours_rss_i0 ON w_sejours_rss USING btree (oid); CREATE INDEX w_sejours_rss_i1 ON w_sejours_rss USING btree (rss_id); CREATE INDEX w_sejours_rss_i2 ON w_sejours_rss USING btree (sejour_id); CREATE INDEX w_sejours_rss_i3 ON w_sejours_rss USING btree (no_sejour); -- Traduction des règles en oid RAISE NOTICE '%' , 'Application des regles. Traduction en oid'; DROP TABLE IF EXISTS w_filiere_soin_rule; CREATE TEMP TABLE w_filiere_soin_rule AS SELECT t_filiere_soin_rule.oid, filiere_soin_id, CASE WHEN priorite <> 0 THEN priorite WHEN liste_diagnostic_principal <> '' THEN 90000 ELSE 999999 END AS priorite, CASE WHEN liste_finess <> '' THEN '1' ELSE '0' END AS a_liste_finess, string_to_array(translate(liste_finess,'*,','% '),' ') AS liste_finess, NULL::bigint[] AS liste_finess_id , CASE WHEN liste_diagnostic_principal <> '' THEN '1' ELSE '0' END AS a_liste_diagnostic_principal, string_to_array(translate(liste_diagnostic_principal,'*,','% '),' ') AS liste_diagnostic_principal, NULL::bigint[] AS liste_diagnostic_principal_id , CASE WHEN liste_diagnostic_relie <> '' THEN '1' ELSE '0' END AS a_liste_diagnostic_relie, string_to_array(translate(liste_diagnostic_relie,'*,','% '),' ') AS liste_diagnostic_relie, NULL::bigint[] AS liste_diagnostic_relie_id , CASE WHEN liste_diagnostic_associe <> '' THEN '1' ELSE '0' END AS a_liste_diagnostic_associe, string_to_array(translate(liste_diagnostic_associe,'*,','% '),' ') AS liste_diagnostic_associe, NULL::bigint[] AS liste_diagnostic_associe_id , CASE WHEN liste_acte <> '' THEN '1' ELSE '0' END AS a_liste_acte, string_to_array(translate(liste_acte,'*,','% '),' ') AS liste_acte, NULL::bigint[] AS liste_acte_pmsi_id , NULL::bigint[] AS liste_acte_base_id , CASE WHEN liste_ghm <> '' THEN '1' ELSE '0' END AS a_liste_ghm, string_to_array(translate(liste_ghm,'*,','% '),' ') AS liste_ghm, NULL::bigint[] AS liste_ghm_pmsi_id, NULL::bigint[] AS liste_ghm_activite_id, liste_ghm AS liste_ghm_origine, CASE WHEN liste_sauf_ghm <> '' THEN '1' ELSE '0' END AS a_liste_sauf_ghm, string_to_array(translate(liste_sauf_ghm,'*,','% '),' ') AS liste_sauf_ghm, NULL::bigint[] AS liste_sauf_ghm_pmsi_id , NULL::bigint[] AS liste_sauf_ghm_activite_id , liste_sauf_ghm AS liste_sauf_ghm_origine, CASE WHEN liste_type_sejour <> '' THEN '1' ELSE '0' END AS a_liste_type_sejour, string_to_array(translate(liste_type_sejour,'*,','% '),' ') AS liste_type_sejour, NULL::text[] AS liste_type_sejour_id , CASE WHEN liste_unite_fonctionnelle <> '' THEN '1' ELSE '0' END AS a_liste_unite_fonctionnelle, string_to_array(translate(liste_unite_fonctionnelle,'*,','% '),' ') AS liste_unite_fonctionnelle, NULL::bigint[] AS liste_unite_fonctionnelle_id , CASE WHEN liste_service <> '' THEN '1' ELSE '0' END AS a_liste_service, string_to_array(translate(liste_service,'*,','% '),' ') AS liste_service, NULL::bigint[] AS liste_service_id , CASE WHEN liste_etage <> '' THEN '1' ELSE '0' END AS a_liste_etage, string_to_array(translate(liste_etage,'*,','% '),' ') AS liste_etage, NULL::bigint[] AS liste_etage_id , CASE WHEN liste_unite_fonctionnelle_entree <> '' THEN '1' ELSE '0' END AS a_liste_unite_fonctionnelle_entree, string_to_array(translate(liste_unite_fonctionnelle_entree,'*,','% '),' ') AS liste_unite_fonctionnelle_entree, NULL::bigint[] AS liste_unite_fonctionnelle_entree_id , CASE WHEN liste_service_entree <> '' THEN '1' ELSE '0' END AS a_liste_service_entree, string_to_array(translate(liste_service_entree,'*,','% '),' ') AS liste_service_entree, NULL::bigint[] AS liste_service_entree_id , CASE WHEN liste_etage_entree <> '' THEN '1' ELSE '0' END AS a_liste_etage_entree, string_to_array(translate(liste_etage_entree,'*,','% '),' ') AS liste_etage_entree, NULL::bigint[] AS liste_etage_entree_id , CASE WHEN liste_activite <> '' THEN '1' ELSE '0' END AS a_liste_activite, string_to_array(translate(liste_activite,'*,','% '),' ') AS liste_activite, NULL::bigint[] AS liste_activite_id , CASE WHEN liste_medecin <> '' THEN '1' ELSE '0' END AS a_liste_medecin, string_to_array(CASE WHEN liste_medecin NOT LIKE '%**%' THEN translate(liste_medecin,'*,','% ') ELSE liste_medecin END,' ') AS liste_medecin, NULL::bigint[] AS liste_medecin_pmsi_id , NULL::bigint[] AS liste_medecin_activite_id , CASE WHEN liste_specialite <> '' THEN '1' ELSE '0' END AS a_liste_specialite, string_to_array(translate(liste_specialite,'*,','% '),' ') AS liste_specialite, NULL::bigint[] AS liste_specialite_activite_id , CASE WHEN liste_rubrique <> '' THEN '1' ELSE '0' END AS a_liste_rubrique, string_to_array(translate(liste_rubrique,'*,','% '),' ') AS liste_rubrique, NULL::bigint[] AS liste_rubrique_id, CASE WHEN liste_prestation <> '' THEN '1' ELSE '0' END AS a_liste_prestation, string_to_array(translate(liste_prestation,'*,','% '),' ') AS liste_prestation, NULL::bigint[] AS liste_prestation_id FROM activite.t_filiere_soin_rule t_filiere_soin_rule JOIN activite.t_filiere_soin t_filiere_soin ON filiere_soin_id = t_filiere_soin.oid ORDER BY priorite, filiere_soin_id; UPDATE w_filiere_soin_rule SET liste_finess_id = (SELECT base.cti_group_array3(oid) FROM base.t_finess WHERE code LIKE ANY (liste_finess)) WHERE a_liste_finess = '1'; IF _module_pmsimco = '1' THEN UPDATE w_filiere_soin_rule SET liste_diagnostic_principal_id = (SELECT base.cti_group_array3(oid) FROM pmsi.t_diagnostics WHERE code LIKE ANY (liste_diagnostic_principal)) WHERE a_liste_diagnostic_principal = '1'; UPDATE w_filiere_soin_rule SET liste_diagnostic_relie_id = (SELECT base.cti_group_array3(oid) FROM pmsi.t_diagnostics WHERE code LIKE ANY (liste_diagnostic_relie)) WHERE a_liste_diagnostic_relie = '1'; UPDATE w_filiere_soin_rule SET liste_diagnostic_associe_id = (SELECT base.cti_group_array3(oid) FROM pmsi.t_diagnostics WHERE code LIKE ANY (liste_diagnostic_associe)) WHERE a_liste_diagnostic_associe = '1'; UPDATE w_filiere_soin_rule SET liste_acte_pmsi_id = (SELECT base.cti_group_array3(oid) FROM pmsi.t_actes WHERE code LIKE ANY (liste_acte) AND code <> '') WHERE a_liste_acte = '1'; DROP TABLE IF EXISTS w_filiere_soin_rule_actes_pmsi; CREATE TEMP TABLE w_filiere_soin_rule_actes_pmsi AS SELECT t_actes.oid AS rule_acte_id, w_filiere_soin_rule.oid AS rule_id FROM pmsi.t_actes JOIN w_filiere_soin_rule ON code LIKE ANY (liste_acte); CREATE INDEX w_filiere_soin_rule_actes_pmsi_i1 ON w_filiere_soin_rule_actes_pmsi USING btree (rule_acte_id); END IF; DROP TABLE IF EXISTS w_filiere_soin_rule_actes_base; CREATE TEMP TABLE w_filiere_soin_rule_actes_base AS SELECT t_actes.oid AS rule_acte_id, w_filiere_soin_rule.oid AS rule_id FROM base.t_actes JOIN w_filiere_soin_rule ON code LIKE ANY (liste_acte) AND code <> ''; CREATE INDEX w_filiere_soin_rule_actes_base_i1 ON w_filiere_soin_rule_actes_base USING btree (rule_acte_id); DROP TABLE IF EXISTS w_filiere_soin_rule_rubriques; CREATE TEMP TABLE w_filiere_soin_rule_rubriques AS SELECT t_rubriques_facturation.oid AS rule_rubrique_id, w_filiere_soin_rule.oid AS rule_id FROM activite.t_rubriques_facturation JOIN w_filiere_soin_rule ON code LIKE ANY (liste_rubrique) AND code <> ''; CREATE INDEX w_filiere_soin_rule_rubriques_i1 ON w_filiere_soin_rule_rubriques USING btree (rule_rubrique_id); DROP TABLE IF EXISTS w_filiere_soin_rule_prestations; CREATE TEMP TABLE w_filiere_soin_rule_prestations AS SELECT t_prestations.oid AS rule_prestation_id, w_filiere_soin_rule.oid AS rule_id FROM activite.t_prestations JOIN w_filiere_soin_rule ON code LIKE ANY (liste_prestation) AND code <> ''; CREATE INDEX w_filiere_soin_rule_prestations_i1 ON w_filiere_soin_rule_prestations USING btree (rule_prestation_id); UPDATE w_filiere_soin_rule SET liste_acte_base_id = (SELECT base.cti_group_array3(oid) FROM base.t_actes WHERE code LIKE ANY (liste_acte)) WHERE a_liste_acte = '1' ; IF _module_pmsimco = '1' THEN UPDATE w_filiere_soin_rule SET liste_ghm_pmsi_id = (SELECT base.cti_group_array3(oid) FROM pmsi.t_ghm WHERE code LIKE ANY (liste_ghm)) WHERE a_liste_ghm = '1'; UPDATE w_filiere_soin_rule SET liste_ghm_pmsi_id = array_cat(liste_ghm_pmsi_id, (SELECT base.cti_group_array3(t_ghm.oid) FROM pmsi.t_ghm JOIN base.t_cas ON cas_id = t_cas.oid WHERE '[CAS:'||t_cas.code||']' LIKE ANY (liste_ghm)) ) WHERE a_liste_ghm = '1' AND liste_ghm_origine LIKE '%[CAS:%' ; END IF; UPDATE w_filiere_soin_rule SET liste_ghm_activite_id = (SELECT base.cti_group_array3(ghm_id) FROM activite.t_ghm_c WHERE ghm_code LIKE ANY (liste_ghm)) WHERE a_liste_ghm = '1' ; UPDATE w_filiere_soin_rule SET liste_ghm_activite_id = array_cat(liste_ghm_activite_id, (SELECT base.cti_group_array3(t_ghm.oid) FROM base.t_ghm JOIN base.t_cas ON cas_id = t_cas.oid WHERE '[CAS:'||t_cas.code||']' LIKE ANY (liste_ghm)) ) WHERE a_liste_ghm = '1' AND liste_ghm_origine LIKE '%[CAS:%' ; IF _module_pmsimco = '1' THEN UPDATE w_filiere_soin_rule SET liste_sauf_ghm_pmsi_id = (SELECT base.cti_group_array3(oid) FROM pmsi.t_ghm WHERE code LIKE ANY (liste_sauf_ghm)) WHERE a_liste_sauf_ghm = '1'; END IF; UPDATE w_filiere_soin_rule SET liste_sauf_ghm_activite_id = (SELECT base.cti_group_array3(ghm_id) FROM activite.t_ghm_c WHERE ghm_code LIKE ANY (liste_sauf_ghm)) WHERE a_liste_sauf_ghm = '1' ; IF _module_pmsimco = '1' THEN UPDATE w_filiere_soin_rule SET liste_medecin_pmsi_id = ( SELECT base.cti_group_array3(t_medecins_pmsi.oid) FROM pmsi.t_medecins t_medecins_pmsi LEFT JOIN base.t_medecins ON t_medecins_pmsi.medecin_reference_id = t_medecins.oid WHERE t_medecins_pmsi.oid <> 0 AND t_medecins_pmsi.code <> '' AND t_medecins_pmsi.code LIKE ANY (liste_medecin) AND liste_medecin[1] <> '(R)' OR t_medecins.oid <> 0 AND t_medecins.code <> '' AND t_medecins.code LIKE ANY (liste_medecin) AND liste_medecin[1] = '(R)' ) WHERE a_liste_medecin = '1'; END IF; UPDATE w_filiere_soin_rule SET liste_medecin_activite_id = ( SELECT base.cti_group_array3(t_medecins_administratifs.oid) FROM activite.t_medecins_administratifs LEFT JOIN base.t_medecins ON t_medecins_administratifs.medecin_id = t_medecins.oid WHERE ( t_medecins_administratifs.oid <> 0 AND t_medecins_administratifs.code <> '' AND t_medecins_administratifs.code LIKE ANY (liste_medecin) AND liste_medecin[1] <> '(R)' ) OR ( t_medecins_administratifs.oid IN ( SELECT to_id FROM activite.t_classes JOIN activite.t_classes_sections ON t_classes_sections.classe_id = t_classes.oid JOIN activite.t_classes_sections_elements ON t_classes_sections_elements.section_id = t_classes_sections.oid WHERE '[CLASSE:'||t_classes.code||':'||t_classes_sections.code||']' = ANY(liste_medecin) ) ) OR ( t_medecins.oid <> 0 AND t_medecins.code <> '' AND t_medecins.code LIKE ANY (liste_medecin) AND liste_medecin[1] = '(R)' ) ) WHERE a_liste_medecin = '1' ; UPDATE w_filiere_soin_rule SET liste_specialite_activite_id = (SELECT base.cti_group_array3(oid) FROM base.t_specialites_medecin WHERE code LIKE ANY (liste_specialite)) WHERE a_liste_specialite = '1' ; UPDATE w_filiere_soin_rule SET liste_type_sejour_id = (SELECT base.cti_group_array3(code) FROM activite.t_type_sejour WHERE code <> '' AND code LIKE ANY (liste_type_sejour)) WHERE a_liste_type_sejour = '1' ; UPDATE w_filiere_soin_rule SET liste_unite_fonctionnelle_id = (SELECT base.cti_group_array3(oid) FROM activite.t_unites_fonctionnelles WHERE code LIKE ANY (liste_unite_fonctionnelle)) WHERE a_liste_unite_fonctionnelle = '1' ; UPDATE w_filiere_soin_rule SET liste_service_id = (SELECT base.cti_group_array3(oid) FROM activite.t_services_facturation WHERE code LIKE ANY (liste_service)) WHERE a_liste_service = '1' ; UPDATE w_filiere_soin_rule SET liste_etage_id = (SELECT base.cti_group_array3(oid) FROM activite.t_etages WHERE code LIKE ANY (liste_etage)) WHERE a_liste_etage = '1' ; UPDATE w_filiere_soin_rule SET liste_unite_fonctionnelle_entree_id = (SELECT base.cti_group_array3(oid) FROM activite.t_unites_fonctionnelles WHERE code LIKE ANY (liste_unite_fonctionnelle_entree)) WHERE a_liste_unite_fonctionnelle_entree = '1' ; UPDATE w_filiere_soin_rule SET liste_service_entree_id = (SELECT base.cti_group_array3(oid) FROM activite.t_services_facturation WHERE code LIKE ANY (liste_service_entree)) WHERE a_liste_service_entree = '1' ; UPDATE w_filiere_soin_rule SET liste_etage_entree_id = (SELECT base.cti_group_array3(oid) FROM activite.t_etages WHERE code LIKE ANY (liste_etage_entree)) WHERE a_liste_etage_entree = '1' ; UPDATE w_filiere_soin_rule SET liste_activite_id = (SELECT base.cti_group_array3(oid) FROM activite.t_activites WHERE code LIKE ANY (liste_activite)) WHERE a_liste_activite = '1' ; UPDATE w_filiere_soin_rule SET liste_rubrique_id = (SELECT base.cti_group_array3(oid) FROM activite.t_rubriques_facturation WHERE code LIKE ANY (liste_rubrique)) WHERE a_liste_rubrique = '1' ; UPDATE w_filiere_soin_rule SET liste_prestation_id = (SELECT base.cti_group_array3(oid) FROM activite.t_prestations WHERE code LIKE ANY (liste_prestation)) WHERE a_liste_prestation = '1' ; -- Association cles aux rubriques RAISE NOTICE '%' , 'Application des regles. Traitement des rubriques'; DROP TABLE IF EXISTS w_factures_rubriques; CREATE TEMP TABLE w_factures_rubriques AS SELECT p_factures.no_sejour, rule_id FROM activite.p_factures_lignes_c JOIN activite.p_factures ON p_factures.no_facture = p_factures_lignes_c.no_facture JOIN w_filiere_soin_rule_rubriques ON p_factures_lignes_c.rubrique_facturation_id = rule_rubrique_id WHERE p_factures_lignes_c.montant_facture <> 0 GROUP BY 1,2 HAVING SUM(p_factures_lignes_c.montant_facture) > 0 UNION SELECT p_factures.no_sejour, rule_id FROM activite.p_factures_lignes_non_facturees_c JOIN activite.p_factures ON p_factures.no_facture = p_factures_lignes_non_facturees_c.no_facture JOIN w_filiere_soin_rule_rubriques ON p_factures_lignes_non_facturees_c.rubrique_facturation_id = rule_rubrique_id ; CREATE INDEX w_factures_rubriques_i1 ON w_factures_rubriques USING btree (no_sejour); DROP TABLE IF EXISTS w_filiere_soin_rubriques; CREATE TEMP TABLE w_filiere_soin_rubriques AS SELECT oid, base.cti_group_array3(rubrique_rule_id) AS rubrique_liste_rule_id FROM ( SELECT w_sejours_rss.oid, rule_id AS rubrique_rule_id FROM w_factures_rubriques JOIN w_sejours_rss ON w_factures_rubriques.no_sejour = w_sejours_rss.no_sejour ) subview GROUP BY 1; ALTER TABLE w_filiere_soin_rubriques ADD CONSTRAINT w_filiere_soin_rubriques_pkey PRIMARY KEY(oid); UPDATE w_sejours_rss SET rubrique_liste_rule_id = w_filiere_soin_rubriques.rubrique_liste_rule_id FROM w_filiere_soin_rubriques WHERE w_filiere_soin_rubriques.oid = w_sejours_rss.oid; -- Association cles aux prestations RAISE NOTICE '%' , 'Application des regles. Traitement des prestations'; DROP TABLE IF EXISTS w_factures_prestations; CREATE TEMP TABLE w_factures_prestations AS SELECT p_factures.no_sejour, rule_id FROM activite.p_factures_lignes_c JOIN activite.p_factures ON p_factures.no_facture = p_factures_lignes_c.no_facture JOIN w_filiere_soin_rule_prestations ON p_factures_lignes_c.prestation_id = rule_prestation_id WHERE p_factures_lignes_c.montant_facture <> 0 GROUP BY 1,2 HAVING SUM(p_factures_lignes_c.montant_facture) > 0 UNION SELECT p_factures.no_sejour, rule_id FROM activite.p_factures_lignes_non_facturees_c JOIN activite.p_factures ON p_factures.no_facture = p_factures_lignes_non_facturees_c.no_facture JOIN w_filiere_soin_rule_prestations ON p_factures_lignes_non_facturees_c.prestation_id = rule_prestation_id GROUP BY 1,2 ; CREATE INDEX w_factures_prestations_i1 ON w_factures_prestations USING btree (no_sejour); DROP TABLE IF EXISTS w_filiere_soin_prestations; CREATE TEMP TABLE w_filiere_soin_prestations AS SELECT oid, base.cti_group_array3(prestation_rule_id) AS prestation_liste_rule_id FROM ( SELECT w_sejours_rss.oid, rule_id AS prestation_rule_id FROM w_factures_prestations JOIN w_sejours_rss ON w_factures_prestations.no_sejour = w_sejours_rss.no_sejour ) subview GROUP BY 1; ALTER TABLE w_filiere_soin_prestations ADD CONSTRAINT w_filiere_soin_prestations_pkey PRIMARY KEY(oid); UPDATE w_sejours_rss SET prestation_liste_rule_id = w_filiere_soin_prestations.prestation_liste_rule_id FROM w_filiere_soin_prestations WHERE w_filiere_soin_prestations.oid = w_sejours_rss.oid; -- Association cles aux actes RAISE NOTICE '%' , 'Application des regles. Traitement des actes'; DROP TABLE IF EXISTS w_factures_actes; CREATE TEMP TABLE w_factures_actes AS SELECT no_facture, rule_id FROM activite.p_factures_lignes_h JOIN w_filiere_soin_rule_actes_base ON p_factures_lignes_h.acte_id = rule_acte_id WHERE activite_ccam <> '4' UNION SELECT no_facture, rule_id FROM activite.p_factures_lignes_non_facturees_h JOIN w_filiere_soin_rule_actes_base ON p_factures_lignes_non_facturees_h.acte_id = rule_acte_id WHERE activite_ccam <> '4'; CREATE INDEX w_factures_actes_i1 ON w_factures_actes USING btree (no_facture); DROP TABLE IF EXISTS w_filiere_soin_actes; IF _module_pmsimco = '1' THEN CREATE TEMP TABLE w_filiere_soin_actes AS SELECT oid, base.cti_group_array3(acte_rule_id) AS acte_liste_rule_id FROM ( SELECT w_sejours_rss.oid, rule_id AS acte_rule_id FROM pmsi.p_rss_actes JOIN w_sejours_rss ON p_rss_actes.rss_id = w_sejours_rss.rss_id JOIN w_filiere_soin_rule_actes_pmsi ON p_rss_actes.acte_id = rule_acte_id UNION SELECT w_sejours_rss.oid, rule_id AS acte_rule_id FROM w_factures_actes JOIN activite.p_factures ON w_factures_actes.no_facture = p_factures.no_facture JOIN w_sejours_rss ON p_factures.no_sejour = w_sejours_rss.no_sejour ) subview GROUP BY 1; ELSE CREATE TEMP TABLE w_filiere_soin_actes AS SELECT oid, base.cti_group_array3(acte_rule_id) AS acte_liste_rule_id FROM ( SELECT w_sejours_rss.oid, rule_id AS acte_rule_id FROM w_factures_actes JOIN activite.p_factures ON w_factures_actes.no_facture = p_factures.no_facture JOIN w_sejours_rss ON p_factures.no_sejour = w_sejours_rss.no_sejour ) subview GROUP BY 1; END IF; ALTER TABLE w_filiere_soin_actes ADD CONSTRAINT w_filiere_soin_actes_pkey PRIMARY KEY(oid); UPDATE w_sejours_rss SET acte_liste_rule_id = w_filiere_soin_actes.acte_liste_rule_id FROM w_filiere_soin_actes WHERE w_filiere_soin_actes.oid = w_sejours_rss.oid; -- Diagnostics IF _module_pmsimco = '1' THEN RAISE NOTICE '%' , 'Application des regles. Traitement des diagnostics'; DROP TABLE IF EXISTS w_filiere_soin_diagnostics; CREATE TEMP TABLE w_filiere_soin_diagnostics AS SELECT w_sejours_rss.oid, base.cti_group_array3(w_filiere_soin_rule.oid) AS diagnostic_associe_liste_rule_id FROM pmsi.p_rss_diagnostics JOIN w_filiere_soin_rule ON type_diagnostic_rss IN ('DA', 'DS') AND diagnostic_id = ANY (liste_diagnostic_associe_id) JOIN w_sejours_rss ON p_rss_diagnostics.rss_id = w_sejours_rss.rss_id WHERE a_liste_diagnostic_associe <> '0' GROUP BY 1; ALTER TABLE w_filiere_soin_diagnostics ADD CONSTRAINT w_filiere_soin_diagnostics_pkey PRIMARY KEY(oid); UPDATE w_sejours_rss SET diagnostic_associe_liste_rule_id = w_filiere_soin_diagnostics.diagnostic_associe_liste_rule_id FROM w_filiere_soin_diagnostics WHERE w_filiere_soin_diagnostics.oid = w_sejours_rss.oid; END IF; -- Mise à jour des cles venant des données du PMSI RAISE NOTICE '%' , 'Application des regles. Attribution des formes activite venant du pmsi'; DROP TABLE IF EXISTS w_sejours_filiere_soin_rule; CREATE TEMP TABLE w_sejours_filiere_soin_rule AS SELECT w_sejours_rss.oid, w_filiere_soin_rule.oid AS rule_id, 'P'::text AS source, priorite, w_filiere_soin_rule.filiere_soin_id FROM w_sejours_rss JOIN w_filiere_soin_rule ON (a_liste_finess = '0' OR finess_id = ANY (liste_finess_id)) AND (a_liste_medecin = '0' OR medecin_rss_id = ANY (liste_medecin_pmsi_id)) AND (a_liste_type_sejour = '0') AND (a_liste_unite_fonctionnelle = '0') AND (a_liste_service = '0') AND (a_liste_etage = '0') AND (a_liste_unite_fonctionnelle_entree = '0') AND (a_liste_service_entree = '0') AND (a_liste_etage_entree = '0') AND (a_liste_activite = '0') AND (a_liste_specialite = '0' OR specialite_sejour_id = ANY (liste_specialite_activite_id)) AND (a_liste_diagnostic_principal = '0' OR diagnostic_principal_id = ANY (liste_diagnostic_principal_id)) AND (a_liste_diagnostic_relie = '0' OR diagnostic_relie_id = ANY (liste_diagnostic_relie_id)) AND (a_liste_diagnostic_associe = '0' OR w_filiere_soin_rule.oid = ANY(diagnostic_associe_liste_rule_id)) AND (a_liste_acte = '0' OR w_filiere_soin_rule.oid = ANY(acte_liste_rule_id)) AND (a_liste_ghm = '0' OR ghm_pmsi_id = ANY (liste_ghm_pmsi_id)) AND (a_liste_sauf_ghm = '0' OR ghm_pmsi_id <> ALL (liste_sauf_ghm_pmsi_id)) AND (a_liste_prestation = '0') AND (a_liste_rubrique = '0') WHERE w_sejours_rss.rss_id <> 0 GROUP BY 1,2,3,4,5 ORDER BY 1; -- Mise à jour des cles venant des données d'activite RAISE NOTICE '%' , 'Application des regles. Attribution des formes activite venant de la GAP'; INSERT INTO w_sejours_filiere_soin_rule SELECT w_sejours_rss.oid, w_filiere_soin_rule.oid AS rule_id, 'A'::text AS source, priorite, w_filiere_soin_rule.filiere_soin_id FROM w_sejours_rss JOIN w_filiere_soin_rule ON (a_liste_finess = '0' OR finess_id = ANY (liste_finess_id)) AND (a_liste_type_sejour = '0' OR type_sejour = ANY (liste_type_sejour_id)) AND (a_liste_unite_fonctionnelle = '0' OR unite_fonctionnelle_id = ANY (liste_unite_fonctionnelle_id)) AND (a_liste_service = '0' OR service_facturation_id = ANY (liste_service_id)) AND (a_liste_etage = '0' OR etage_id = ANY (liste_etage_id)) AND (a_liste_unite_fonctionnelle_entree = '0' OR unite_fonctionnelle_entree_id = ANY (liste_unite_fonctionnelle_entree_id)) AND (a_liste_service_entree = '0' OR service_facturation_entree_id = ANY (liste_service_entree_id)) AND (a_liste_etage_entree = '0' OR etage_entree_id = ANY (liste_etage_entree_id)) AND (a_liste_activite = '0' OR activite_id = ANY (liste_activite_id)) AND (a_liste_medecin = '0' OR medecin_sejour_id = ANY (liste_medecin_activite_id)) AND (a_liste_specialite = '0' OR specialite_sejour_id = ANY (liste_specialite_activite_id)) AND (a_liste_diagnostic_principal = '0' OR diagnostic_principal_id = ANY (liste_diagnostic_principal_id)) AND (a_liste_diagnostic_relie = '0' OR diagnostic_relie_id = ANY (liste_diagnostic_relie_id)) AND (a_liste_diagnostic_associe = '0' OR w_filiere_soin_rule.oid = ANY(diagnostic_associe_liste_rule_id)) AND (a_liste_acte = '0' OR w_filiere_soin_rule.oid = ANY(acte_liste_rule_id)) AND (a_liste_rubrique = '0' OR w_filiere_soin_rule.oid = ANY(rubrique_liste_rule_id)) AND (a_liste_prestation = '0' OR w_filiere_soin_rule.oid = ANY(prestation_liste_rule_id)) AND (a_liste_ghm = '0' OR ghm_activite_id = ANY (liste_ghm_activite_id)) AND (a_liste_sauf_ghm = '0' OR ghm_activite_id <> ALL (liste_sauf_ghm_activite_id)) WHERE w_sejours_rss.sejour_id <> 0 GROUP BY 1,2,3,4,5 ORDER BY 1; RAISE NOTICE '%' , 'Application des regles. Filiere principale'; DROP TABLE IF EXISTS w_sejours_filiere_soin; CREATE TEMP TABLE w_sejours_filiere_soin AS SELECT w_sejours_filiere_soin_rule.oid, MIN(priorite) AS filiere_soin_priorite, ((MIN(ARRAY[to_char(priorite,'FM000000000000')||source,filiere_soin_id::text]))[2])::bigint AS filiere_soin_id FROM w_sejours_filiere_soin_rule GROUP BY 1 ORDER BY 1; UPDATE w_sejours_rss SET filiere_soin_id = w_sejours_filiere_soin.filiere_soin_id, filiere_soin_priorite = w_sejours_filiere_soin.filiere_soin_priorite FROM w_sejours_filiere_soin WHERE w_sejours_rss.oid = w_sejours_filiere_soin.oid ; RAISE NOTICE '%' , 'Application des regles. Deductions depuis utilisation'; RAISE NOTICE '%' , 'Application des regles. Validation des filieres'; UPDATE activite.p_sejours SET filiere_soin_principale_id = w_sejours_rss.filiere_soin_id FROM w_sejours_rss WHERE p_sejours.oid = w_sejours_rss.sejour_id AND p_sejours.oid <> 0 AND ( p_sejours.filiere_soin_principale_id IS DISTINCT FROM w_sejours_rss.filiere_soin_id ); ANALYSE activite.p_sejours ; TRUNCATE activite.p_sejour_filiere_soin ; INSERT INTO activite.p_sejour_filiere_soin (sejour_id, filiere_soin_id ) SELECT w_sejours_rss.oid, COALESCE(w_sejours_filiere_soin_rule.filiere_soin_id,0) AS filiere_soin_id FROM w_sejours_rss LEFT JOIN w_sejours_filiere_soin_rule ON w_sejours_rss.oid = w_sejours_filiere_soin_rule.oid GROUP BY 1,2 ; ANALYSE activite.p_sejours ; INSERT INTO activite.p_oids (code_table, oid) SELECT 'filiere_soin', filiere_soin_id FROM activite.p_sejour_filiere_soin WHERE filiere_soin_id NOT IN (SELECT oid FROM activite.p_oids WHERE code_table = 'filiere_soin') GROUP BY 2; RETURN 'OK'; END;