return: text lang: plpgsql src: | DECLARE result TEXT; BEGIN -- Pour initialiser l'identification des factures sans montant établissement INSERT INTO activite.t_divers (code, texte, valeur, description) SELECT 'AJUSTFILDELEAU', 'Ajustement données fil de l''eau PMSI', '0', '0=Non, 1=Oui ' WHERE 'AJUSTFILDELEAU' NOT IN (SELECT code FROM activite.t_divers); IF NOT EXISTS (SELECT * FROM activite.t_divers WHERE t_divers.code = 'AJUSTFILDELEAU' AND t_divers.valeur = '1' LIMIT 1) THEN return 'Non paramétré'; END IF; IF NOT EXISTS (SELECT * FROM pg_tables WHERE schemaname = 'pmsi' AND tablename = 'p_rss') THEN return 'Pas de PMSI'; END IF; -- Mise à jour données -- Séjours non groupés dans activité sans correspondance dans PMSI DROP TABLE IF EXISTS w_rss_new; CREATE TEMP TABLE w_rss_new AS SELECT nextval('pmsi.s_rss'::regclass) AS rss_id, no_sejour FROM activite.p_factures_reference WHERE nb_non_groupe = 1 AND ltrim(no_sejour,'0') NOT IN (SELECT ltrim(no_sejour_administratif,'0') FROM pmsi.p_rss WHERE etat = '') AND code_sorti = '1' AND date_sortie >= '20150101' AND date_sortie - date_entree < 300; INSERT INTO pmsi.p_rss ( finess, oid, no_rss, no_patient, version_groupage, date_naissance, sexe, date_entree, date_sortie, mode_entree, provenance, mode_sortie, destination, code_postal, poids_bebe, igs2, cma, groupe_ghm, duree_sejour, nb_rsa, age, supprime, date_import, nb_rum, secteur, no_sejour_administratif, nb_seances, ghm_fg9, ghm_id, medecin_rss_id, ghs_id, mois_sortie, diagnostic_principal_id, diagnostic_relie_id, ghm_production_id, no_rum_principal, unite_medicale_principale_id, import_id, etat, acte_principal_id, code_postal_id, patient_id, prestation_principale_id, severite_fg11_simulation_code, en_cours, en_cours_etat, base_remboursement, sejour_facture, honoraires_factures, t2a_facture, dmi_facture, phc_facture, ca_ghs_theorique, nb_ghs, ca_ghs, nb_exb, ca_exb, nb_exh, ca_exh, nb_si, ca_si, nb_sur, ca_sur, nb_rea, ca_rea, nb_neonat, ca_neonat, traitement_epmsi, code_retour_groupage, comite_medical_id, rehosp_meme_ghm, from_oid ) SELECT (SELECt MAX(FINESS) FROM pmsi.p_rss WHERE en_cours = '1') AS finess, w_rss_new.rss_id AS oid, 0 AS no_rss, 0 AS no_patient, '*A' AS version_groupage, date_naissance AS date_naissance, p_patients.code_sexe AS sexe, p_sejours.date_entree, p_sejours.date_sortie, p_sejours.mode_entree, p_sejours.provenance, p_sejours.mode_sortie, p_sejours.destination, '' AS code_postal, 0 AS poids_bebe, 0 AS igs2, '' AS cma, '' AS groupe_ghm, CASE WHEN p_sejours.date_sortie > p_sejours.date_entree THEN date(p_sejours.date_sortie) - date(p_sejours.date_entree) ELSE 0 END AS duree_sejour, 1 AS nb_rsa, CASE WHEN p_sejours.date_sortie > date_naissance AND p_sejours.date_sortie - date_naissance BETWEEN 0 AND 50000 THEN trunc((date(p_sejours.date_entree) - date(date_naissance)) / 365.25,0) ELSE 0 END AS age, '' AS supprime, now() AS date_import, 1 AS nb_rum, '' AS secteur, p_sejours.no_sejour AS no_sejour_administratif, 0 AS nb_seances, '' AS ghm_fg9, COALESCE(t_ghm.oid, 0) AS ghm_id, 0 AS medecin_rss_id, 0 AS ghs_id, date_part('year', p_sejours.date_sortie) * 100 + date_part('month', p_sejours.date_sortie) AS mois_sortie, 0 AS diagnostic_principal_id, 0 AS diagnostic_relie_id, COALESCE(t_ghm.oid, 0) AS ghm_production_id, 1 AS no_rum_principal, 0 AS unite_medicale_principale_id, -1 AS import_id, '' AS etat, 0 AS acte_principal_id, 0 AS code_postal_id, 0 AS patient_id, 0 AS prestation_principale_id, '' AS severite_fg11_simulation_code, '1' AS en_cours, 'S' AS en_cours_etat, 0 AS base_remboursement, 0 AS sejour_facture, 0 AS honoraires_factures, 0 AS t2a_facture, 0 AS dmi_facture, 0 AS phc_facture, 0 AS ca_ghs_theorique, 0 AS nb_ghs, 0 AS ca_ghs, 0 AS nb_exb, 0 AS ca_exb, 0 AS nb_exh, 0 AS ca_exh, 0 AS nb_si, 0 AS ca_si, 0 AS nb_sur, 0 AS ca_sur, 0 AS nb_rea, 0 AS ca_rea, 0 AS nb_neonat, 0 AS ca_neonat, '' AS traitement_epmsi, '' AS code_retour_groupage, 0 AS comite_medical_id, '0' AS rehosp_meme_ghm, 0 AS from_oid FROM w_rss_new JOIN activite.p_sejours ON p_sejours.no_sejour = w_rss_new.no_sejour JOIN activite.p_patients On p_sejours.no_patient = p_patients.no_patient LEFT JOIN pmsi.t_ghm ON t_ghm.code = '99Z99Z'; INSERT INTO pmsi.p_identites( rss_id, no_rss, nom, prenom, nom_naissance) SELECT w_rss_new.rss_id AS oid, 0 AS no_rss, nom, prenom, nom_naissance FROM w_rss_new JOIN activite.p_sejours ON p_sejours.no_sejour = w_rss_new.no_sejour JOIN activite.p_patients On p_sejours.no_patient = p_patients.no_patient; INSERT INTO pmsi.p_rss_rum( rss_id, no_rss, no_rum, date_entree, date_sortie, mode_entree, provenance, mode_sortie, destination, duree_sejour, nb_seances, unite_medicale, diagnostic_principal_id, diagnostic_relie_id, unite_medicale_id, type_autorisation, igs2, type_autorisation_lit_dedie, supplement_code) SELECT w_rss_new.rss_id AS rss_id, 0 AS no_rss, 1 AS no_rum, p_sejours.date_entree, p_sejours.date_sortie, p_sejours.mode_entree, p_sejours.provenance, p_sejours.mode_sortie, p_sejours.destination, CASE WHEN p_sejours.date_sortie > p_sejours.date_entree THEN date(p_sejours.date_sortie) - date(p_sejours.date_entree) ELSE 0 END AS duree_sejour, 0 AS nb_seances, t_unites_medicales_pmsi.code AS unite_medicale, 0 AS diagnostic_principal_id, 0 AS diagnostic_relie_id, 0 AS unite_medicale_id, '' AS type_autorisation, 0 AS igs2, '' AS type_autorisation_lit_dedie, '' AS supplement_code FROM w_rss_new JOIN activite.p_sejours ON p_sejours.no_sejour = w_rss_new.no_sejour JOIN activite.p_patients On p_sejours.no_patient = p_patients.no_patient JOIN activite.t_lieux ON lieu_sortie_id = t_lieux.oid LEFT JOIN activite.t_unites_medicales on t_lieux.unite_medicale_id = t_unites_medicales.oid LEFT JOIN activite.t_unites_fonctionnelles on t_lieux.unite_fonctionnelle_id = t_unites_fonctionnelles.oid LEFT JOIN pmsi.t_unites_medicales t_unites_medicales_pmsi On (CASE WHEN t_lieux.unite_medicale_id <> 0 THEN t_unites_medicales.code ELSE t_unites_fonctionnelles.code END) = t_unites_medicales_pmsi.code; INSERT INTO pmsi.p_rsf_total( finess, no_rss, code_pec, rang_beneficiaire, regime, nature_pec, justificatif_exo, no_facture, code_regularisation, base_remboursement, sejour_facture, sejour_remboursable, honoraires_factures, honoraires_remboursable, t2a_facture, dmi_facture, phc_facture, participation_assure_avant_oc, sejour_remboursable_2, honoraires_remboursable_2, montant_dmi_ghs2006, nb_si, ca_si, nb_sur, ca_sur, nb_rea, ca_rea, nb_neonat, ca_neonat, nb_exh, ca_exh, nb_exb, ca_exb, nb_ghs, ca_ghs, rss_id, ca_ghs_theorique) SELECT p_rss.finess, p_rss.no_rss, '', '', '', '', '', '', '', 0, 0, 0, 0, 0, 0, 0, 0, 0, 0, 0, 0, 0, 0, 0, 0, 0, 0, 0, 0, 0, 0, 0, 0, 0, 0, p_rss.oid, 0 FROM pmsi.p_rss LEFT JOIN pmsi.p_rsf_total ON (p_rsf_total.rss_id = p_rss.oid) WHERE en_cours = '1' AND p_rsf_total.rss_id IS NULL; INSERT INTO pmsi.p_rss_etat ( rss_id, est_groupe, est_valide, date_groupage, est_facture, date_facture ) SELECT w_rss_new.rss_id, '0' AS est_groupe, '0' AS est_valide, '20991231' AS date_groupage, '0' AS est_facture, '20991231' AS date_facture FROM w_rss_new WHERE rss_id NOT IN (SELECT rss_id FROM pmsi.p_rss_etat); -- Séjours externes dans PMSi sans facturation ets dans activité à supprimer DROP TABLE IF EXISTS w_rss_to_delete; CREATE TEMP TABLE w_rss_to_delete AS SELECT p_rss.oid AS rss_id FROM pmsi.p_rss JOIN activite.p_factures_reference ON p_factures_reference.no_sejour = p_rss.no_sejour_administratif WHERE p_rss.date_sortie >= '20140101' AND p_rss.en_cours = '1' AND p_factures_reference.montant_facture_c = 0 AND nb_non_calcules = 0; INSERT INTO w_rss_to_delete SELECT p_rss.oid AS rss_id FROM pmsi.p_rss JOIN activite.p_factures_reference ON p_factures_reference.no_sejour = p_rss.no_sejour_administratif WHERE p_rss.date_sortie >= '20140101' AND p_rss.en_cours = '1' AND nb_non_groupe = 0 AND nb_groupe = 0 AND en_cours_etat <> 'F'; DELETE FROM pmsi.p_identites WHERE rss_id IN (SELECT rss_id FROM w_rss_to_delete); DELETE FROM pmsi.p_rss_rum WHERE rss_id IN (SELECT rss_id FROM w_rss_to_delete); DELETE FROM pmsi.p_rss_diagnostics WHERE rss_id IN (SELECT rss_id FROM w_rss_to_delete); DELETE FROM pmsi.p_rss_actes WHERE rss_id IN (SELECT rss_id FROM w_rss_to_delete); DELETE FROM pmsi.p_rss_lpp WHERE rss_id IN (SELECT rss_id FROM w_rss_to_delete); DELETE FROM pmsi.p_rss_ucd WHERE rss_id IN (SELECT rss_id FROM w_rss_to_delete); DELETE FROM pmsi.p_rsf_total WHERE rss_id IN (SELECT rss_id FROM w_rss_to_delete); DELETE FROM pmsi.p_rsf_detail WHERE rss_id IN (SELECT rss_id FROM w_rss_to_delete); DELETE FROM pmsi.p_rss_etat WHERE rss_id IN (SELECT rss_id FROM w_rss_to_delete); DELETE FROM pmsi.p_rss WHERE oid IN (SELECT rss_id FROM w_rss_to_delete); -- Séjours facturés donc forcément validés et facturés UPDATE pmsi.p_rss SET en_cours_etat = 'F' FROM activite.p_factures_reference WHERE en_cours = '1' AND no_sejour = no_sejour_administratif AND en_cours_etat IN ('G','V') AND nb_groupe = 1 AND nb_non_groupe = 0 AND nb_non_calcules = 0; -- Séjours PMSI non facturés dans activité UPDATE pmsi.p_rss SET en_cours_etat = 'V' FROM activite.p_factures_reference WHERE en_cours = '1' AND no_sejour = no_sejour_administratif AND en_cours_etat = 'F' AND nb_groupe = 1 AND nb_non_groupe = 0 AND nb_non_calcules = 1; UPDATE pmsi.p_rss_etat SET est_facture = '0' FROM pmsi.p_rss JOIN activite.p_factures_reference ON no_sejour = no_sejour_administratif WHERE p_rss_etat.rss_id = p_rss.oid AND en_cours = '1' AND est_facture = '1' AND nb_non_calcules = 1; -- Séjours activité non validés dans PMSI UPDATE activite.p_factures_reference SET nb_non_groupe = 1 , nb_groupe = 0 FROM pmsi.p_rss JOIN pmsi.t_ghm ON p_rss.ghm_id = t_ghm.oid AND t_ghm.code NOT LIKE '15%' WHERE no_sejour = no_sejour_administratif AND en_cours = '1' AND en_cours_etat = 'G' AND nb_groupe = 1 AND nb_non_groupe = 0; UPDATE activite.p_factures_reference_tiers p_factures_reference SET nb_non_groupe = 1 , nb_groupe = 0 FROM pmsi.p_rss JOIN pmsi.t_ghm ON p_rss.ghm_id = t_ghm.oid AND t_ghm.code NOT LIKE '15%' WHERE no_sejour = no_sejour_administratif AND en_cours = '1' AND en_cours_etat = 'G' AND nb_groupe = 1 AND nb_non_groupe = 0; UPDATE activite.p_factures_reference SET nb_non_groupe = 1 , nb_groupe = 0 FROM pmsi.p_rss JOIN pmsi.t_ghm ON p_rss.ghm_id = t_ghm.oid AND t_ghm.code NOT LIKE '15%' WHERE no_sejour = no_sejour_administratif AND en_cours = '1' AND en_cours_etat = 'S' AND nb_groupe = 1 AND nb_non_groupe = 0; UPDATE activite.p_factures_reference_tiers p_factures_reference SET nb_non_groupe = 1 , nb_groupe = 0 FROM pmsi.p_rss JOIN pmsi.t_ghm ON p_rss.ghm_id = t_ghm.oid AND t_ghm.code NOT LIKE '15%' WHERE no_sejour = no_sejour_administratif AND en_cours = '1' AND en_cours_etat = 'S' AND nb_groupe = 1 AND nb_non_groupe = 0; -- Mise à jour des séjours UPDATE activite.p_sejours SET ghs_id = 0 FROM activite.p_factures_reference WHERE p_factures_reference.no_sejour = p_sejours.no_sejour AND p_sejours.ghs_id <> 0 AND nb_non_groupe = 1; UPDATE activite.p_sejours SET date_facture = '20991231' FROM activite.p_factures_reference WHERE p_factures_reference.no_sejour = p_sejours.no_sejour AND p_sejours.date_facture <> '20991231' AND nb_non_calcules = 1; UPDATE activite.p_factures SET ghs_id = 0 FROM activite.p_factures_reference WHERE p_factures_reference.no_facture_reference = p_factures.no_facture_reference AND p_factures.ghs_id <> 0 AND nb_non_groupe = 1; -- Mise à jour ME/MS/PROV/DEST depuis PMSI si non renseigné dans Activité WITH w_rss as ( SELECT no_sejour_administratif, date_naissance, lpad((MIN(ARRAY[to_char(date_entree, 'YYYYMMDD'), mode_entree]))[2], 1, '8') as mode_entree, lpad((MIN(ARRAY[to_char(date_entree, 'YYYYMMDD'), provenance]))[2], 1, '0') as provenance, lpad((MAX(ARRAY[to_char(date_sortie, 'YYYYMMDD'), mode_sortie]))[2], 1, '8') as mode_sortie, lpad((MAX(ARRAY[to_char(date_sortie, 'YYYYMMDD'), destination]))[2], 1, '0') as destination FROM pmsi.p_rss WHERE p_rss.date_sortie >= date_trunc('year', now() - interval '2 year')::date GROUP BY 1,2 ) UPDATE activite.p_sejours SET mode_entree = w_rss.mode_entree, mode_sortie = w_rss.mode_sortie, provenance = w_rss.provenance, destination = w_rss.destination FROM w_rss, activite.p_patients WHERE p_sejours.no_patient = p_patients.no_patient AND w_rss.no_sejour_administratif = p_sejours.no_sejour AND w_rss.date_naissance = p_patients.date_naissance AND ( 1!=1 OR (p_sejours.mode_entree = '8' AND p_sejours.mode_entree != w_rss.mode_entree) OR (p_sejours.mode_sortie = '8' AND p_sejours.mode_sortie != w_rss.mode_sortie) OR (p_sejours.provenance = '0' AND p_sejours.provenance != w_rss.provenance) OR (p_sejours.destination = '0' AND p_sejours.destination != w_rss.destination) ); RETURN 'OK'; END;