return: text lang: plpgsql src: | DECLARE result TEXT; BEGIN RAISE NOTICE '%' , 'Suppression des elements de la table p_rss_rea'; TRUNCATE pmsi.p_rss_rea; RAISE NOTICE '%' , 'listes utilisees par l''etude REA'; DROP TABLE IF EXISTS w_listes_rea ; CREATE TEMP TABLE w_listes_rea AS SELECT liste_code, to_id FROM pmsi.v_listes_3 WHERE v_listes_3.liste_code IN ('CTI_VIT15_10A', 'CTI_VIT15_20A') ; ----------------------- ** RAISE NOTICE '%' , 'Creation table temp_pmsi000378_rss'; --Table temp_pmsi000378_rss : -- --finess ................................ : Finess du RSS --no_rss ................................ : Numéro du RSS --oid ................................... : Id du RSS --date_sortie ........................... : Date de sortie du RSS --age ................................... : Age du patient --rea_facturee_nb_rss ................... : REA facturé (1 ou 0) --rea_facturee_nb_prestations ........... : Nombre de REA facturés --rea_facturee_base_remboursement ....... : Montant des REA facturés --rea_facturable_nb_rss ................. : REA facturable (1 ou 0) --rea_facturable_nb_prestations ......... : Nombre de REA facturables --rea_facturable_base_remboursement ..... : Montant des REA facturables --rea_facturable_regle .................. : Numéro de la règle qui permet de facturer un REA --rea_facturable_regle_justificatif ..... : Texte de la règle qui permet de facturer un REA --rea_passage_nb_rss .................... : Passage dans une UM avec autorisation '01' (REA) --rea_passage_duree_sejour .............. : Nombre de jours dans l'UM avec autorisation '03' --rea_passage_base_remboursement ........ : S/O --rea_facturable_sans_rea_ni_igs_nb_rss . : DROP TABLE IF EXISTS temp_pmsi000378_rss; CREATE TEMP TABLE temp_pmsi000378_rss( finess character(9), no_rss bigint, oid bigint, date_sortie date, age integer, rea_facturee_nb_rss numeric(5) DEFAULT 0, rea_facturee_nb_prestations numeric(5) DEFAULT 0, rea_facturee_base_remboursement numeric(11, 2) DEFAULT 0, rea_facturable_nb_rss numeric(5) DEFAULT 0, rea_facturable_nb_prestations numeric(5) DEFAULT 0, rea_facturable_base_remboursement numeric(11, 2) DEFAULT 0, rea_facturable_regle character(1) DEFAULT '', rea_facturable_regle_justificatif character varying(255) DEFAULT '', rea_passage_nb_rss numeric(5) DEFAULT 0, rea_passage_duree_sejour numeric(5) DEFAULT 0, rea_passage_base_remboursement numeric(11, 2) DEFAULT 0, rea_facturable_sans_rea_ni_igs_nb_rss numeric(5) DEFAULT 0 ); CREATE INDEX temp_pmsi000378_rss_i1 ON temp_pmsi000378_rss USING btree (oid); ----------------------- ** RAISE NOTICE '%' , 'Creation table temp_pmsi000367_rsf_detail'; --Table temp_pmsi000367_rsf_detail : -- --date_debut ............ : Date d'entrée dans le RUM --date_fin .............. : Date de sortie du RUM --nombre ................ : Nombre de journées dans le RUM (minimum 1) --prix_unitaire ......... : Tarif unitaire du supplément juournalier --base_remboursement .... : Montant total du supplément journalier --coefficient_mco ....... : Coefficient MCO --prestation_id ......... : Identifiant de la prestation --regle ................. : Numéro de la règle d'attribution d'un supplément REA --rss_id ................ : Identifiant du Séjour DROP TABLE IF EXISTS temp_pmsi000367_rsf_detail; CREATE TEMP TABLE temp_pmsi000367_rsf_detail ( date_debut date, date_fin date, nombre numeric(13,2) DEFAULT 1, prix_unitaire numeric(13,2) DEFAULT 0, base_remboursement numeric(13,2) DEFAULT 0, coefficient_mco numeric(5,4) DEFAULT 0, prestation_id bigint DEFAULT 0, regle character(1) DEFAULT '', rss_id bigint DEFAULT 0 ); ----------------------- ** RAISE NOTICE '%' , 'Selection de tous les dossiers'; INSERT INTO temp_pmsi000378_rss(finess, no_rss, oid, date_sortie, age) SELECT finess, no_rss, oid AS rss_id, date_sortie, age FROM pmsi.p_rss WHERE p_rss.etat <> 'S'; ----------------------- ** RAISE NOTICE '%' , 'Dossiers avec supplement REA facture'; UPDATE temp_pmsi000378_rss SET rea_facturee_nb_rss = nb_rss, rea_facturee_nb_prestations = nb_prestations, rea_facturee_base_remboursement = base_remboursement FROM ( SELECT rss_id, 1 as nb_rss, SUM(nombre) as nb_prestations, SUM(base_remboursement) as base_remboursement FROM pmsi.p_rsf_detail JOIN temp_pmsi000378_rss ON temp_pmsi000378_rss.oid = p_rsf_detail.rss_id JOIN pmsi.t_prestations ON t_prestations.oid = p_rsf_detail.prestation_id WHERE 1=1 AND est_ligne_rss = '1' AND t_prestations.code = 'REA' GROUP BY rss_id ) subview WHERE subview.rss_id = temp_pmsi000378_rss.oid; ----------------------- ** RAISE NOTICE '%' , 'Dossiers passes dans une UM qui possede une autorisation REA'; UPDATE temp_pmsi000378_rss SET rea_passage_nb_rss = nb_rss, rea_passage_duree_sejour = duree_sejour FROM ( SELECT rss_id, 1 as nb_rss, SUM(duree_sejour) as duree_sejour FROM pmsi.p_rss_rum JOIN temp_pmsi000378_rss ON temp_pmsi000378_rss.oid = p_rss_rum.rss_id JOIN pmsi.t_unites_medicales ON p_rss_rum.unite_medicale_id = t_unites_medicales.oid WHERE t_unites_medicales.type_autorisation LIKE '01%' GROUP BY rss_id ) subview WHERE subview.rss_id = temp_pmsi000378_rss.oid; ----------------------- ** RAISE NOTICE '%' , 'Reinitialise les codes de supplement dans la table des RUMs'; UPDATE pmsi.p_rss_rum SET supplement_code = '' FROM temp_pmsi000378_rss WHERE p_rss_rum.rss_id = temp_pmsi000378_rss.oid AND (supplement_code IS NULL OR supplement_code <> ''); ----------------------- ** RAISE NOTICE '%' , 'Suppression de tables temporaires'; DROP TABLE IF EXISTS w_rss_rea_1; DROP TABLE IF EXISTS w_rss_rea_2; ----------------------- ** RAISE NOTICE '%' , 'Dossiers avec un acte dans la liste 1 de l''annexe 10 de la norme B2'; CREATE TEMP TABLE w_rss_rea_1 AS SELECT rss_id, no_rum FROM pmsi.p_rss_actes JOIN temp_pmsi000378_rss ON p_rss_actes.rss_id = temp_pmsi000378_rss.oid JOIN w_listes_rea ON w_listes_rea.to_id = p_rss_actes.acte_id WHERE 1=1 AND temp_pmsi000378_rss.date_sortie BETWEEN '20120101'::date AND '20990228'::date AND w_listes_rea.liste_code = 'CTI_VIT15_10A'; ----------------------- ** RAISE NOTICE '%' , 'Dossiers avec un acte de la liste 2 de l''annexe 10 realise au moins 3 fois'; CREATE TEMP TABLE w_rss_rea_2 AS SELECT rss_id, no_rum, acte_id, count(*) FROM pmsi.p_rss_actes JOIN temp_pmsi000378_rss ON p_rss_actes.rss_id = temp_pmsi000378_rss.oid JOIN w_listes_rea ON w_listes_rea.to_id = p_rss_actes.acte_id WHERE 1=1 AND temp_pmsi000378_rss.date_sortie BETWEEN '20120101'::date AND '20990228'::date AND w_listes_rea.liste_code = 'CTI_VIT15_20A' GROUP BY rss_id, no_rum, acte_id HAVING count(*) >= 3; ----------------------- ** ----------------------- ** RAISE NOTICE '%' , 'Positionne un supplement REA1 si acte dans liste 1 annexe 10 et ((IGS2 >= 15 et age >= 18) ou (age < 18) et RUM avec autorisation ''01'''; UPDATE pmsi.p_rss_rum SET supplement_code = 'REA1' FROM temp_pmsi000378_rss , w_rss_rea_1 WHERE temp_pmsi000378_rss.oid = p_rss_rum.rss_id AND temp_pmsi000378_rss.date_sortie BETWEEN '20120101'::date AND '20990228'::date AND supplement_code = '' AND ((p_rss_rum.igs2 >= 15 AND temp_pmsi000378_rss.age >= 18) OR temp_pmsi000378_rss.age < 18) AND unite_medicale_id IN (SELECT oid FROM pmsi.t_unites_medicales WHERE type_autorisation LIKE '01%') AND p_rss_rum.rss_id = w_rss_rea_1.rss_id AND p_rss_rum.no_rum = w_rss_rea_1.no_rum; ----------------------- ** RAISE NOTICE '%' , 'Positionne un supplement REA2 si acte dans liste 2 annexe 7 realise 3 fois et ((IGS2 >= 15 et age >= 18) ou (age < 18) et RUM avec autorisation ''01'''; UPDATE pmsi.p_rss_rum SET supplement_code = 'REA2' FROM temp_pmsi000378_rss , w_rss_rea_2 WHERE temp_pmsi000378_rss.oid = p_rss_rum.rss_id AND temp_pmsi000378_rss.date_sortie BETWEEN '20120101'::date AND '20990228'::date AND supplement_code = '' AND ((p_rss_rum.igs2 >= 15 AND temp_pmsi000378_rss.age >= 18) OR temp_pmsi000378_rss.age < 18) AND unite_medicale_id IN (SELECT oid FROM pmsi.t_unites_medicales WHERE type_autorisation LIKE '01%') AND p_rss_rum.rss_id = w_rss_rea_2.rss_id AND p_rss_rum.no_rum = w_rss_rea_2.no_rum; ----------------------- ** RAISE NOTICE 'Remplit la table avec tous les RUMs precedemment marqués comme facturables (REA1, REA2)'; INSERT INTO temp_pmsi000367_rsf_detail( date_debut, date_fin, regle, nombre, prix_unitaire, base_remboursement, coefficient_mco, rss_id) SELECT p_rss_rum.date_entree, p_rss_rum.date_sortie, SUBSTR(supplement_code, 4 , 1), CASE WHEN p_rss_rum.date_sortie > p_rss_rum.date_entree THEN CASE WHEN p_rss_rum.mode_sortie <> '9' THEN p_rss_rum.date_sortie - p_rss_rum.date_entree ELSE p_rss_rum.date_sortie - p_rss_rum.date_entree + 1 END ELSE 1 END, CASE WHEN t_finess.type_etablissement = '1' THEN CASE WHEN temp_pmsi000378_rss.date_sortie >= t_prestations.date_debut_prive_1 AND temp_pmsi000378_rss.date_sortie <= t_prestations.date_fin_prive_1 THEN t_prestations.tarif_prive_1 WHEN temp_pmsi000378_rss.date_sortie >= t_prestations.date_debut_prive_2 AND temp_pmsi000378_rss.date_sortie <= t_prestations.date_fin_prive_2 THEN t_prestations.tarif_prive_2 WHEN temp_pmsi000378_rss.date_sortie >= t_prestations.date_debut_prive_3 AND temp_pmsi000378_rss.date_sortie <= t_prestations.date_fin_prive_3 THEN t_prestations.tarif_prive_3 WHEN temp_pmsi000378_rss.date_sortie >= t_prestations.date_debut_prive_4 AND temp_pmsi000378_rss.date_sortie <= t_prestations.date_fin_prive_4 THEN t_prestations.tarif_prive_4 WHEN temp_pmsi000378_rss.date_sortie >= t_prestations.date_debut_prive_5 AND temp_pmsi000378_rss.date_sortie <= t_prestations.date_fin_prive_5 THEN t_prestations.tarif_prive_5 WHEN temp_pmsi000378_rss.date_sortie >= t_prestations.date_debut_prive_6 AND temp_pmsi000378_rss.date_sortie <= t_prestations.date_fin_prive_6 THEN t_prestations.tarif_prive_6 WHEN temp_pmsi000378_rss.date_sortie >= t_prestations.date_debut_prive_7 AND temp_pmsi000378_rss.date_sortie <= t_prestations.date_fin_prive_7 THEN t_prestations.tarif_prive_7 WHEN temp_pmsi000378_rss.date_sortie >= t_prestations.date_debut_prive_8 AND temp_pmsi000378_rss.date_sortie <= t_prestations.date_fin_prive_8 THEN t_prestations.tarif_prive_8 WHEN temp_pmsi000378_rss.date_sortie >= t_prestations.date_debut_prive_9 AND temp_pmsi000378_rss.date_sortie <= t_prestations.date_fin_prive_9 THEN t_prestations.tarif_prive_9 ELSE 0::numeric END ELSE CASE WHEN temp_pmsi000378_rss.date_sortie >= t_prestations.date_debut_public_1 AND temp_pmsi000378_rss.date_sortie <= t_prestations.date_fin_public_1 THEN t_prestations.tarif_public_1 WHEN temp_pmsi000378_rss.date_sortie >= t_prestations.date_debut_public_2 AND temp_pmsi000378_rss.date_sortie <= t_prestations.date_fin_public_2 THEN t_prestations.tarif_public_2 WHEN temp_pmsi000378_rss.date_sortie >= t_prestations.date_debut_public_3 AND temp_pmsi000378_rss.date_sortie <= t_prestations.date_fin_public_3 THEN t_prestations.tarif_public_3 WHEN temp_pmsi000378_rss.date_sortie >= t_prestations.date_debut_public_4 AND temp_pmsi000378_rss.date_sortie <= t_prestations.date_fin_public_4 THEN t_prestations.tarif_public_4 WHEN temp_pmsi000378_rss.date_sortie >= t_prestations.date_debut_public_5 AND temp_pmsi000378_rss.date_sortie <= t_prestations.date_fin_public_5 THEN t_prestations.tarif_public_5 WHEN temp_pmsi000378_rss.date_sortie >= t_prestations.date_debut_public_6 AND temp_pmsi000378_rss.date_sortie <= t_prestations.date_fin_public_6 THEN t_prestations.tarif_public_6 WHEN temp_pmsi000378_rss.date_sortie >= t_prestations.date_debut_public_7 AND temp_pmsi000378_rss.date_sortie <= t_prestations.date_fin_public_7 THEN t_prestations.tarif_public_7 WHEN temp_pmsi000378_rss.date_sortie >= t_prestations.date_debut_public_8 AND temp_pmsi000378_rss.date_sortie <= t_prestations.date_fin_public_8 THEN t_prestations.tarif_public_8 WHEN temp_pmsi000378_rss.date_sortie >= t_prestations.date_debut_public_9 AND temp_pmsi000378_rss.date_sortie <= t_prestations.date_fin_public_9 THEN t_prestations.tarif_public_9 ELSE 0::numeric END END, 0, 1, temp_pmsi000378_rss.oid FROM pmsi.p_rss_rum JOIN temp_pmsi000378_rss ON temp_pmsi000378_rss.oid = p_rss_rum.rss_id JOIN base.t_finess ON t_finess.code = temp_pmsi000378_rss.finess ,pmsi.t_prestations WHERE 1=1 AND supplement_code <> '' AND t_prestations.code = 'REA'; ----------------------- ** RAISE NOTICE ' '; UPDATE temp_pmsi000367_rsf_detail SET nombre = temp_pmsi000367_rsf_detail.nombre - 1 FROM temp_pmsi000378_rss, temp_pmsi000367_rsf_detail temp_pmsi000367_rsf_detail2 WHERE temp_pmsi000367_rsf_detail.rss_id = temp_pmsi000378_rss.oid AND temp_pmsi000367_rsf_detail.date_debut <> temp_pmsi000367_rsf_detail.date_fin AND temp_pmsi000367_rsf_detail2.rss_id = temp_pmsi000378_rss.oid AND temp_pmsi000367_rsf_detail2.date_debut = temp_pmsi000367_rsf_detail.date_debut AND temp_pmsi000367_rsf_detail2.date_fin = temp_pmsi000367_rsf_detail2.date_debut; ----------------------- ** RAISE NOTICE ' '; UPDATE temp_pmsi000367_rsf_detail SET base_remboursement = round( CASE WHEN temp_pmsi000378_rss.date_sortie >= t_finess.date_debut_coefficient_mco_9 THEN t_finess.coefficient_mco_9 WHEN temp_pmsi000378_rss.date_sortie >= t_finess.date_debut_coefficient_mco_8 THEN t_finess.coefficient_mco_8 WHEN temp_pmsi000378_rss.date_sortie >= t_finess.date_debut_coefficient_mco_7 THEN t_finess.coefficient_mco_7 WHEN temp_pmsi000378_rss.date_sortie >= t_finess.date_debut_coefficient_mco_6 THEN t_finess.coefficient_mco_6 WHEN temp_pmsi000378_rss.date_sortie >= t_finess.date_debut_coefficient_mco_5 THEN t_finess.coefficient_mco_5 WHEN temp_pmsi000378_rss.date_sortie >= t_finess.date_debut_coefficient_mco_4 THEN t_finess.coefficient_mco_4 WHEN temp_pmsi000378_rss.date_sortie >= t_finess.date_debut_coefficient_mco_3 THEN t_finess.coefficient_mco_3 WHEN temp_pmsi000378_rss.date_sortie >= t_finess.date_debut_coefficient_mco_2 THEN t_finess.coefficient_mco_2 WHEN temp_pmsi000378_rss.date_sortie >= t_finess.date_debut_coefficient_mco_1 THEN t_finess.coefficient_mco_1 ELSE 1::numeric END, 2) * prix_unitaire * nombre FROM pmsi.t_prestations, base.t_finess, temp_pmsi000378_rss WHERE temp_pmsi000367_rsf_detail.prestation_id = t_prestations.oid AND temp_pmsi000367_rsf_detail.rss_id = temp_pmsi000378_rss.oid AND temp_pmsi000378_rss.finess = t_finess.code; ----------------------- ** RAISE NOTICE 'Ressence tous les REA facturables à partir des regles calculees precedemment'; UPDATE temp_pmsi000378_rss SET rea_facturable_nb_rss = nb_rss, rea_facturable_nb_prestations = nb_prestations, rea_facturable_base_remboursement = base_remboursement, rea_facturable_regle = regle FROM (SELECT rss_id, 1 as nb_rss, SUM(nombre) as nb_prestations, SUM(base_remboursement) as base_remboursement, MAX(regle) as regle FROM temp_pmsi000367_rsf_detail GROUP BY rss_id) subview WHERE subview.rss_id = temp_pmsi000378_rss.oid; ----------------------- ** RAISE NOTICE ' '; UPDATE temp_pmsi000378_rss SET rea_facturable_regle_justificatif = 'Passé en REA non facturable ('::text ||' éligible)'::text FROM w_rss_rea_1 WHERE w_rss_rea_1.rss_id = temp_pmsi000378_rss.oid AND rea_facturee_nb_rss = 0 AND rea_facturable_nb_rss = 0 AND rea_passage_nb_rss > 0; UPDATE temp_pmsi000378_rss SET rea_facturable_regle_justificatif = 'Passé en REA non facturable ('::text || ' éligible)'::text FROM w_rss_rea_2 WHERE w_rss_rea_2.rss_id = temp_pmsi000378_rss.oid AND rea_facturee_nb_rss = 0 AND rea_facturable_nb_rss = 0 AND rea_passage_nb_rss > 0; UPDATE temp_pmsi000378_rss SET rea_facturable_regle_justificatif = 'Passé en REA non facturable' WHERE rea_facturee_nb_rss = 0 AND rea_facturable_nb_rss = 0 AND rea_passage_nb_rss > 0 AND rea_facturable_regle_justificatif = ''; UPDATE temp_pmsi000378_rss SET rea_facturable_regle_justificatif = 'Règle '::text || rea_facturable_regle::text FROM w_rss_rea_1 WHERE w_rss_rea_1.rss_id = temp_pmsi000378_rss.oid AND rea_facturable_regle = '1'; UPDATE temp_pmsi000378_rss SET rea_facturable_regle_justificatif = 'Règle '::text || rea_facturable_regle::text FROM w_rss_rea_2 WHERE w_rss_rea_2.rss_id = temp_pmsi000378_rss.oid AND rea_facturable_regle = '2'; ----------------------- ** RAISE NOTICE ' '; UPDATE temp_pmsi000378_rss SET rea_facturable_sans_rea_ni_igs_nb_rss = 1, rea_facturable_regle_justificatif = 'Vérifier REA ('::text || ' éligible)'::text FROM w_rss_rea_1 WHERE w_rss_rea_1.rss_id = temp_pmsi000378_rss.oid AND rea_passage_nb_rss = 0; UPDATE temp_pmsi000378_rss SET rea_facturable_sans_rea_ni_igs_nb_rss = 1, rea_facturable_regle_justificatif = 'Vérifier REA ('::text || ' éligible)'::text FROM w_rss_rea_2 WHERE w_rss_rea_2.rss_id = temp_pmsi000378_rss.oid AND rea_passage_nb_rss = 0; DELETE FROM temp_pmsi000378_rss WHERE rea_facturee_nb_rss = 0 AND rea_facturable_nb_rss = 0 AND rea_passage_nb_rss = 0 AND rea_facturable_sans_rea_ni_igs_nb_rss = 0; ----------------------- ** RAISE NOTICE 'Remplissage table p_rss_rea'; INSERT INTO pmsi.p_rss_rea( finess, no_rss, oid, date_sortie, age, rea_facturee_nb_rss, rea_facturee_nb_prestations, rea_facturee_base_remboursement, rea_facturable_nb_rss, rea_facturable_nb_prestations, rea_facturable_base_remboursement, rea_facturable_regle, rea_facturable_regle_justificatif, rea_passage_nb_rss, rea_passage_duree_sejour, rea_passage_base_remboursement, rea_facturable_sans_rea_ni_igs_nb_rss) SELECT * FROM temp_pmsi000378_rss ; RETURN 'OK'; END;