return: text lang: plpgsql src: | DECLARE result TEXT; BEGIN -- Nouvelles colonnes pour compatibilité descendante IF NOT EXISTS ( SELECT column_name FROM information_schema.columns WHERE table_schema || '.' || table_name = 'activite.t_services_facturation' AND column_name = 'activite_par_defaut_id') THEN ALTER TABLE activite.t_services_facturation ADD COLUMN activite_par_defaut_id bigint DEFAULT 0; END IF; IF NOT EXISTS ( SELECT column_name FROM information_schema.columns WHERE table_schema || '.' || table_name = 'activite.t_services_facturation' AND column_name = 'activite_force_id') THEN ALTER TABLE activite.t_services_facturation ADD COLUMN activite_force_id bigint DEFAULT 0; END IF; -- Import de l'historique des lits INSERT INTO activite.t_divers (code, texte, valeur, description) SELECT 'ETALITCSVFILE', 'Emplacement du fichier CSV qui contient l''historique des places', '', 'Emplacement du fichier CSV qui contient l''historique des places' WHERE 'ETALITCSVFILE' NOT IN (SELECT code FROM activite.t_divers) ; IF EXISTS (SELECT valeur FROM activite.t_divers WHERE code = 'ETALITCSVFILE' AND valeur <> '' LIMIT 1) THEN BEGIN DROP TABLE IF EXISTS w_data; CREATE TEMP TABLE w_data ( etage_code text DEFAULT '', etage_id bigint DEFAULT 0, date_debut date, nb_lits_theoriques numeric DEFAULT 0, nb_lits_ouverts numeric DEFAULT 0, nb_box_ambulatoires_theoriques numeric DEFAULT 0, nb_box_ambulatoires_ouverts numeric DEFAULT 0, nb_box_seances_theoriques numeric DEFAULT 0, nb_box_seances_ouverts numeric DEFAULT 0, nb_lits_cp_theoriques numeric DEFAULT 0, nb_lits_cp_ouverts numeric DEFAULT 0, est_ouvert_1 text DEFAULT '1', est_ouvert_2 text DEFAULT '1', est_ouvert_3 text DEFAULT '1', est_ouvert_4 text DEFAULT '1', est_ouvert_5 text DEFAULT '1', est_ouvert_6 text DEFAULT '1', est_ouvert_7 text DEFAULT '1', source text); PERFORM base.cti_execute(' COPY w_data (source) FROM ''' || (SELECT valeur FROM activite.t_divers WHERE code = 'ETALITCSVFILE') || '''' ,1) FROM activite.t_divers WHERE code = 'ETALITCSVFILE' AND valeur <> '' ; UPDATE w_data SET etage_code = split_part(source,';',1), etage_id = t_etages.oid, date_debut = base.cti_to_date(split_part(source,';',3)), nb_lits_theoriques = base.cti_to_number(split_part(source,';',4)), nb_lits_ouverts = base.cti_to_number(split_part(source,';',5)), nb_box_ambulatoires_theoriques = base.cti_to_number(split_part(source,';',6)), nb_box_ambulatoires_ouverts = base.cti_to_number(split_part(source,';',7)), nb_box_seances_theoriques = base.cti_to_number(split_part(source,';',8)), nb_box_seances_ouverts = base.cti_to_number(split_part(source,';',9)), nb_lits_cp_theoriques = base.cti_to_number(split_part(source,';',10)), nb_lits_cp_ouverts = base.cti_to_number(split_part(source,';',11)), est_ouvert_1 = CASE WHEN split_part(source,';',12) IN ('0','N') THEN '0' ELSE '1' END, est_ouvert_2 = CASE WHEN split_part(source,';',13) IN ('0','N') THEN '0' ELSE '1' END, est_ouvert_3 = CASE WHEN split_part(source,';',14) IN ('0','N') THEN '0' ELSE '1' END, est_ouvert_4 = CASE WHEN split_part(source,';',15) IN ('0','N') THEN '0' ELSE '1' END, est_ouvert_5 = CASE WHEN split_part(source,';',16) IN ('0','N') THEN '0' ELSE '1' END, est_ouvert_6 = CASE WHEN split_part(source,';',17) IN ('0','N') THEN '0' ELSE '1' END, est_ouvert_7 = CASE WHEN split_part(source,';',18) IN ('0','N') THEN '0' ELSE '1' END FROM activite.t_etages WHERE split_part(source,';',1) = t_etages.code ; DELETE FROM activite.t_etages_historique USING ( SELECT etage_id, MIN(date_debut) AS date_debut FROM w_data WHERE etage_id <> 0 AND date_debut IS NOT NULL GROUP BY 1 ) subview WHERE t_etages_historique.etage_id = subview.etage_id AND t_etages_historique.date >= subview.date_debut ; INSERT INTO activite.t_etages_historique ( etage_id, date, nb_lits_theoriques, nb_lits_ouverts, nb_box_ambulatoires_theoriques, nb_box_ambulatoires_ouverts, nb_box_seances_theoriques, nb_box_seances_ouverts, nb_lits_cp_theoriques, nb_lits_cp_ouverts, est_ouvert_1, est_ouvert_2, est_ouvert_3, est_ouvert_4, est_ouvert_5, est_ouvert_6, est_ouvert_7 ) SELECT etage_id, date_debut, nb_lits_theoriques, nb_lits_ouverts, nb_box_ambulatoires_theoriques, nb_box_ambulatoires_ouverts, nb_box_seances_theoriques, nb_box_seances_ouverts, nb_lits_cp_theoriques, nb_lits_cp_ouverts, est_ouvert_1, est_ouvert_2, est_ouvert_3, est_ouvert_4, est_ouvert_5, est_ouvert_6, est_ouvert_7 FROM w_data WHERE etage_id <> 0 AND date_debut IS NOT NULL ; EXCEPTION WHEN others THEN RAISE NOTICE 'Erreur %' , 'Import historique des lits CSV'; END; END IF; -- Initialisation valeurs par défaut UPDATE activite.t_services_facturation SET etage_par_defaut_id = 0 WHERE etage_par_defaut_id IS NULL; UPDATE activite.t_services_facturation SET etage_force_id = 0 WHERE etage_force_id IS NULL; UPDATE activite.t_services_facturation SET activite_par_defaut_id = 0 WHERE activite_par_defaut_id IS NULL; UPDATE activite.t_services_facturation SET activite_force_id = 0 WHERE activite_force_id IS NULL; UPDATE activite.t_etages SET service_force_id = 0 WHERE service_force_id IS NULL; UPDATE activite.t_etages SET remplacer_par_valeur_par_defaut = '0' WHERE remplacer_par_valeur_par_defaut IS NULL; UPDATE activite.t_unites_medicales SET etage_par_defaut_id = 0 WHERE etage_par_defaut_id IS NULL; UPDATE activite.t_unites_medicales SET etage_force_id = 0 WHERE etage_force_id IS NULL; INSERT INTO activite.t_lits (oid, texte, texte_court, etage_id, code, chambre_particuliere) SELECT 0, 'Non renseigné', 'Non renseigné', 0, '*', 'N' WHERE 0 NOT IN (SELECT oid FROM activite.t_lits WHERE oid = 0) ; INSERT INTO activite.t_lieux(oid) SELECT 0 WHERE 0 NOT IN (SELECT oid FROM activite.t_lieux WHERE oid = 0) ; WITH to_del AS ( SELECT t_lieux_c.oid FROM activite.t_lieux_c LEFT JOIN activite.t_lieux on t_lieux.oid = t_lieux_c.oid WHERE t_lieux.oid IS NULL ) DELETE FROM activite.t_lieux_c USING to_del WHERE t_lieux_c.oid = to_del.oid ; -- Coherence historique lits IF NOT EXISTS (SELECT * FROM pg_class WHERE relnamespace = pg_my_temp_schema() AND relname = 'w_lit_historique') THEN CREATE TEMP TABLE w_lit_historique (sequence bigint, lit_id bigint, date_debut date, date_fin date, oid bigint); ELSE TRUNCATE w_lit_historique; END IF; IF NOT EXISTS (SELECT * FROM pg_class WHERE relnamespace = pg_my_temp_schema() AND relname = 'w_sequence') THEN CREATE TEMP SEQUENCE w_sequence; ELSE END IF; DELETE FROM activite.t_lit_historique USING ( SELECT lit_id, MIN(date_debut) AS keep_date FROm activite.t_lit_historique GROUP BY 1 having count(*) > 1 AND count(DISTINCT etage_id) = 1 ) subview where t_lit_historique.lit_id = subview.lit_id AND date_debut <> keep_date ; INSERT INTO w_lit_historique SELECT nextval('w_sequence'::regclass) AS sequence, * FROM ( SELECT t_lit_historique.lit_id, date_debut, date_fin, t_lit_historique.oid FROM activite.t_lit_historique ORDER BY 1,2 ) subview; UPDATE activite.t_lit_historique SET date_debut = '00010101' FROM w_lit_historique LEFT JOIN w_lit_historique w_lit_historique_b ON w_lit_historique.lit_id = w_lit_historique_b.lit_id AND w_lit_historique.sequence = w_lit_historique_b.sequence +1 WHERE t_lit_historique.oid = w_lit_historique.oid AND t_lit_historique.date_debut IS DISTINCT FROM '00010101' AND w_lit_historique_b.oid IS NULL; UPDATE activite.t_lit_historique SET date_fin = CASE WHEN w_lit_historique_p.oid IS NULL THEN '20991231' ELSE date(w_lit_historique_p.date_debut - interval '1 day') END FROM w_lit_historique w_lit_historique_2 LEFT JOIN w_lit_historique w_lit_historique_p ON w_lit_historique_2.lit_id = w_lit_historique_p.lit_id AND w_lit_historique_2.sequence = w_lit_historique_p.sequence -1 WHERE t_lit_historique.oid = w_lit_historique_2.oid AND t_lit_historique.date_fin IS DISTINCT FROM CASE WHEN w_lit_historique_p.oid IS NULL THEN '20991231' ELSE date(w_lit_historique_p.date_debut - interval '1 day') END; DELETE FROM activite.t_lit_historique WHERE date_fin < date_debut; -- Forcage service selon etage UPDATE activite.t_lieux SET service_facturation_id = t_etages.service_force_id FROM activite.t_lits JOIN activite.t_etages ON etage_id = t_etages.oid WHERE lit_id = t_lits.oid AND service_force_id <> 0 AND service_facturation_id IS DISTINCT FROM t_etages.service_force_id; -- Forcage activite selon service UPDATE activite.t_lieux SET activite_id = t_services_facturation.activite_par_defaut_id FROM activite.t_services_facturation WHERE service_facturation_id = t_services_facturation.oid AND t_services_facturation.activite_par_defaut_id <> 0 AND t_lieux.activite_id = 0; UPDATE activite.t_lieux SET activite_id = t_services_facturation.activite_force_id FROM activite.t_services_facturation WHERE service_facturation_id = t_services_facturation.oid AND t_services_facturation.activite_force_id <> 0 AND t_lieux.activite_id IS DISTINCT FROM t_services_facturation.activite_force_id; -- Mise à jour t_lieux_c IF NOT EXISTS (SELECT * FROM pg_class WHERE relnamespace = pg_my_temp_schema() AND relname = 'w_lieux_c') THEN CREATE TEMP TABLE w_lieux_c ( oid bigint, date_debut date, date_fin date, from_oid bigint, code_original_1 text, code_original_2 text, code_original_3 text, code_original_4 text, code_original_5 text, code_original_6 text, code_original_7 text, unite_medicale_id bigint, unite_medicale_code text, unite_medicale_texte text, unite_fonctionnelle_id bigint, unite_fonctionnelle_code text, unite_fonctionnelle_texte text, mode_traitement_id bigint, mode_traitement_code text, mode_traitement_texte text, type_t2a character(1), service_facturation_est_sans_mouvement character(1), service_facturation_est_absence character(1), service_facturation_id bigint, service_facturation_code text, service_facturation_texte text, activite_id bigint, activite_code text, activite_texte text, etage_id bigint, etage_code text, etage_texte text, lit_id bigint, lit_code text, lit_texte text, gir_code_original text, gir_id bigint, gir_code text, gir_texte text, gir_coefficient numeric ); ELSE TRUNCATE w_lieux_c; END IF; INSERT INTO w_lieux_c ( oid, date_debut, date_fin, from_oid, code_original_1, code_original_2, code_original_3, code_original_4, code_original_5, code_original_6, code_original_7, unite_medicale_id, unite_medicale_code, unite_medicale_texte, unite_fonctionnelle_id, unite_fonctionnelle_code, unite_fonctionnelle_texte, mode_traitement_id, mode_traitement_code, mode_traitement_texte, service_facturation_id, service_facturation_code, service_facturation_texte, type_t2a, service_facturation_est_sans_mouvement, service_facturation_est_absence, activite_id, activite_code, activite_texte, etage_id, etage_code, etage_texte, lit_id, lit_code, lit_texte, gir_code_original, gir_id, gir_code, gir_texte, gir_coefficient ) SELECT t_lieux.oid, COALESCE(t_lit_historique.date_debut,'00010101') AS date_debut, COALESCE(t_lit_historique.date_fin,'20991231') AS date_fin, t_lieux.oid, code_original_1, code_original_2, code_original_3, code_original_4, code_original_5, code_original_6, code_original_7, t_lieux.unite_medicale_id, t_unites_medicales.code AS unite_medicale_code, t_unites_medicales.texte_court AS unite_medicale_texte, t_lieux.unite_fonctionnelle_id, t_unites_fonctionnelles.code AS unite_fonctionnelle_code, t_unites_fonctionnelles.texte_court AS unite_fonctionnelle_texte, t_services_facturation.mode_traitement_id, t_modes_traitement.code AS mode_traitement_code, t_modes_traitement.texte_court AS mode_traitement_texte, t_lieux.service_facturation_id, t_services_facturation.code AS service_facturation_code, t_services_facturation.texte_court AS service_facturation_texte, t_services_facturation.type_t2a, COALESCE(t_services_facturation.est_sans_mouvement,'0') AS service_facturation_est_sans_mouvement, COALESCE(t_services_facturation.est_absence,'0') AS service_facturation_est_absence, t_lieux.activite_id, t_activites.code AS activite_code, t_activites.texte_court AS activite_texte, CASE WHEN COALESCE(t_services_facturation.etage_force_id,0) IS DISTINCT FROM 0 THEN t_etages_forces_service.oid WHEN COALESCE(t_activites.etage_force_id,0) IS DISTINCT FROM 0 THEN t_etages_forces_activite.oid WHEN COALESCE(t_unites_fonctionnelles.etage_force_id,0) IS DISTINCT FROM 0 AND t_lieux.unite_medicale_id = ANY(etage_force_um_id_array) THEN t_unites_fonctionnelles.etage_force_id WHEN COALESCE(t_unites_fonctionnelles.etage_force2_id,0) IS DISTINCT FROM 0 AND t_lieux.unite_medicale_id = ANY(etage_force2_um_id_array) THEN t_unites_fonctionnelles.etage_force2_id WHEN COALESCE(t_unites_fonctionnelles.etage_force3_id,0) IS DISTINCT FROM 0 AND t_lieux.unite_medicale_id = ANY(etage_force3_um_id_array) THEN t_unites_fonctionnelles.etage_force3_id WHEN COALESCE(t_unites_medicales.etage_force_id,0) IS DISTINCT FROM 0 THEN t_unites_medicales.etage_force_id WHEN COALESCE(t_services_facturation.etage_par_defaut_id,0) IS DISTINCT FROM 0 AND (t_lits.etage_id = 0 OR t_etages.remplacer_par_valeur_par_defaut = '1') AND COALESCE(t_lit_historique.etage_id,0) = 0 THEN t_etages_par_defaut_service.oid WHEN COALESCE(t_activites.etage_par_defaut_id,0) IS DISTINCT FROM 0 AND (t_lits.etage_id = 0 OR t_etages.remplacer_par_valeur_par_defaut = '1') AND COALESCE(t_lit_historique.etage_id,0) = 0 THEN t_etages_par_defaut_activite.oid WHEN COALESCE(t_unites_medicales.etage_par_defaut_id,0) IS DISTINCT FROM 0 AND (t_lits.etage_id = 0 OR t_etages.remplacer_par_valeur_par_defaut = '1') AND COALESCE(t_lit_historique.etage_id,0) = 0 THEN t_etages_par_defaut_um.oid WHEN COALESCE(t_lit_historique.etage_id,0) IS DISTINCT FROM 0 THEN t_lit_historique.etage_id ELSE t_lits.etage_id END AS etage_id, CASE WHEN COALESCE(t_services_facturation.etage_force_id,0) IS DISTINCT FROM 0 THEN t_etages_forces_service.code WHEN COALESCE(t_activites.etage_force_id,0) IS DISTINCT FROM 0 THEN t_etages_forces_activite.code WHEN COALESCE(t_unites_fonctionnelles.etage_force_id,0) IS DISTINCT FROM 0 AND t_lieux.unite_medicale_id = ANY(etage_force_um_id_array) THEN t_etages_forces_uf.code WHEN COALESCE(t_unites_fonctionnelles.etage_force2_id,0) IS DISTINCT FROM 0 AND t_lieux.unite_medicale_id = ANY(etage_force2_um_id_array) THEN t_etages_forces2_uf.code WHEN COALESCE(t_unites_fonctionnelles.etage_force3_id,0) IS DISTINCT FROM 0 AND t_lieux.unite_medicale_id = ANY(etage_force3_um_id_array) THEN t_etages_forces3_uf.code WHEN COALESCE(t_unites_medicales.etage_force_id,0) IS DISTINCT FROM 0 THEN t_etages_forces_um.code WHEN COALESCE(t_services_facturation.etage_par_defaut_id,0) IS DISTINCT FROM 0 AND (t_lits.etage_id = 0 OR t_etages.remplacer_par_valeur_par_defaut = '1') AND COALESCE(t_lit_historique.etage_id,0) = 0 THEN t_etages_par_defaut_service.code WHEN COALESCE(t_activites.etage_par_defaut_id,0) IS DISTINCT FROM 0 AND (t_lits.etage_id = 0 OR t_etages.remplacer_par_valeur_par_defaut = '1') AND COALESCE(t_lit_historique.etage_id,0) = 0 THEN t_etages_par_defaut_activite.code WHEN COALESCE(t_unites_medicales.etage_par_defaut_id,0) IS DISTINCT FROM 0 AND (t_lits.etage_id = 0 OR t_etages.remplacer_par_valeur_par_defaut = '1') AND COALESCE(t_lit_historique.etage_id,0) = 0 THEN t_etages_par_defaut_um.code WHEN COALESCE(t_lit_historique.etage_id,0) IS DISTINCT FROM 0 THEN t_lit_historique_etage.code ELSE t_etages.code END AS etage_code, CASE WHEN COALESCE(t_services_facturation.etage_force_id,0) IS DISTINCT FROM 0 THEN t_etages_forces_service.texte WHEN COALESCE(t_activites.etage_force_id,0) IS DISTINCT FROM 0 THEN t_etages_forces_activite.texte WHEN COALESCE(t_unites_fonctionnelles.etage_force_id,0) IS DISTINCT FROM 0 AND t_lieux.unite_medicale_id = ANY(etage_force_um_id_array) THEN t_etages_forces_uf.texte WHEN COALESCE(t_unites_fonctionnelles.etage_force2_id,0) IS DISTINCT FROM 0 AND t_lieux.unite_medicale_id = ANY(etage_force2_um_id_array) THEN t_etages_forces2_uf.texte WHEN COALESCE(t_unites_fonctionnelles.etage_force3_id,0) IS DISTINCT FROM 0 AND t_lieux.unite_medicale_id = ANY(etage_force3_um_id_array) THEN t_etages_forces3_uf.texte WHEN COALESCE(t_unites_medicales.etage_force_id,0) IS DISTINCT FROM 0 THEN t_etages_forces_um.texte WHEN COALESCE(t_services_facturation.etage_par_defaut_id,0) IS DISTINCT FROM 0 AND (t_lits.etage_id = 0 OR t_etages.remplacer_par_valeur_par_defaut = '1') AND COALESCE(t_lit_historique.etage_id,0) = 0 THEN t_etages_par_defaut_service.texte WHEN COALESCE(t_activites.etage_par_defaut_id,0) IS DISTINCT FROM 0 AND (t_lits.etage_id = 0 OR t_etages.remplacer_par_valeur_par_defaut = '1') AND COALESCE(t_lit_historique.etage_id,0) = 0 THEN t_etages_par_defaut_activite.texte WHEN COALESCE(t_unites_medicales.etage_par_defaut_id,0) IS DISTINCT FROM 0 AND (t_lits.etage_id = 0 OR t_etages.remplacer_par_valeur_par_defaut = '1') AND COALESCE(t_lit_historique.etage_id,0) = 0 THEN t_etages_par_defaut_um.texte WHEN COALESCE(t_lit_historique.etage_id,0) IS DISTINCT FROM 0 THEN t_lit_historique_etage.texte ELSE t_etages.texte END AS etage_texte, t_lieux.lit_id, t_lits.code AS lit_code, t_lits.texte_court AS lit_texte, COALESCE(gir_code_original,'') AS gir_code_original, COALESCE(t_lieux.gir_id,0) AS gir_id, COALESCE(t_gir.code,'') AS gir_code, COALESCE(t_gir.texte_court,'') AS gir_texte, CASE WHEN t_lieux.gir_id > 0 THEN t_gir.coefficient ELSE NULL END FROM activite.t_lieux JOIN activite.t_services_facturation ON t_lieux.service_facturation_id = t_services_facturation.oid JOIN activite.t_activites ON t_lieux.activite_id = t_activites.oid JOIN activite.t_lits ON t_lieux.lit_id = t_lits.oid JOIN activite.t_etages ON t_lits.etage_id = t_etages.oid LEFT JOIN activite.t_lit_historique ON t_lieux.lit_id = t_lit_historique.lit_id LEFT JOIN activite.t_etages t_lit_historique_etage ON t_lit_historique.etage_id = t_lit_historique_etage.oid JOIN activite.t_unites_fonctionnelles ON t_lieux.unite_fonctionnelle_id = t_unites_fonctionnelles.oid JOIN activite.t_unites_medicales ON t_lieux.unite_medicale_id = t_unites_medicales.oid JOIN base.t_modes_traitement ON t_services_facturation.mode_traitement_id = t_modes_traitement.oid LEFT JOIN activite.t_etages t_etages_forces_service ON t_services_facturation.etage_force_id = t_etages_forces_service.oid LEFT JOIN activite.t_etages t_etages_par_defaut_service ON t_services_facturation.etage_par_defaut_id = t_etages_par_defaut_service.oid LEFT JOIN activite.t_etages t_etages_forces_activite ON COALESCE(t_activites.etage_force_id,0) = t_etages_forces_activite.oid LEFT JOIN activite.t_etages t_etages_par_defaut_activite ON COALESCE(t_activites.etage_par_defaut_id,0) = t_etages_par_defaut_activite.oid LEFT JOIN activite.t_etages t_etages_forces_uf ON t_unites_fonctionnelles.etage_force_id = t_etages_forces_uf.oid LEFT JOIN activite.t_etages t_etages_forces2_uf ON t_unites_fonctionnelles.etage_force2_id = t_etages_forces2_uf.oid LEFT JOIN activite.t_etages t_etages_forces3_uf ON t_unites_fonctionnelles.etage_force3_id = t_etages_forces3_uf.oid LEFT JOIN activite.t_etages t_etages_forces_um ON t_unites_medicales.etage_force_id = t_etages_forces_um.oid LEFT JOIN activite.t_etages t_etages_par_defaut_um ON t_unites_medicales.etage_par_defaut_id = t_etages_par_defaut_um.oid LEFT JOIN base.t_gir ON t_lieux.gir_id = t_gir.oid ; PERFORM setval('activite.s_lieux', (SELECT COALESCE(MAX(oid),0) + 1 FROM activite.t_lieux), true); UPDATE w_lieux_c SET oid = nextval('activite.s_lieux'::regclass) WHERE date_debut > '00010101'; UPDATE activite.t_lieux_c SET date_debut = COALESCE(date_debut,'00010101'), date_fin = COALESCE(date_fin,'20991231') WHERE date_debut IS DISTINCT FROM COALESCE(date_debut,'00010101') OR date_fin IS DISTINCT FROM COALESCE(date_fin,'20991231'); -- Forcage séjours IF NOT EXISTS (SELECT * FROM pg_class WHERE relnamespace = pg_my_temp_schema() AND relname = 'w_lieux_new') THEN CREATE TEMP TABLE w_lieux_new ( no_sejour text, lieu_sortie_id bigint, oid bigint, date_debut date, date_fin date, unite_medicale_id bigint, unite_medicale_code text, unite_medicale_texte text, unite_fonctionnelle_id bigint, unite_fonctionnelle_code text, unite_fonctionnelle_texte text, mode_traitement_id bigint, mode_traitement_code text, mode_traitement_texte text, service_facturation_id bigint, service_facturation_code text, service_facturation_texte text, type_t2a character(1), service_facturation_est_sans_mouvement character(1), service_facturation_est_absence character(1), activite_id bigint, activite_code text, activite_texte text, etage_id bigint, etage_code text, etage_texte text, lit_id bigint, lit_code text, lit_texte text, code_original_1 text, code_original_2 text, code_original_3 text, code_original_4 text, code_original_5 text, code_original_6 text, code_original_7 text, gir_code_original text, gir_id bigint, gir_code text, gir_texte text, gir_coefficient numeric ); ELSE TRUNCATE w_lieux_new; END IF; INSERT INTO w_lieux_new SELECT p_sejours.no_sejour, lieu_sortie_id, nextval('activite.s_lieux'::regclass) AS oid, date_debut, date_fin, unite_medicale_id, unite_medicale_code, unite_medicale_texte, unite_fonctionnelle_id, unite_fonctionnelle_code, unite_fonctionnelle_texte, w_lieux_c.mode_traitement_id, mode_traitement_code, mode_traitement_texte, CASE WHEN COALESCE(t_services_facturation.oid,0) <> 0 THEN t_services_facturation.oid ELSE w_lieux_c.service_facturation_id END AS service_facturation_id, CASE WHEN COALESCE(t_services_facturation.oid,0) <> 0 THEN t_services_facturation.code ELSE w_lieux_c.service_facturation_code END AS service_facturation_code, CASE WHEN COALESCE(t_services_facturation.oid,0) <> 0 THEN t_services_facturation.texte ELSE w_lieux_c.service_facturation_texte END AS service_facturation_texte, w_lieux_c.type_t2a, w_lieux_c.service_facturation_est_sans_mouvement, w_lieux_c.service_facturation_est_absence, w_lieux_c.activite_id, activite_code, activite_texte, CASE WHEN COALESCE(t_etages.oid,0) <> 0 THEN t_etages.oid ELSE w_lieux_c.etage_id END AS etage_id, CASE WHEN COALESCE(t_etages.oid,0) <> 0 THEN t_etages.code ELSE w_lieux_c.etage_code END etage_code, CASE WHEN COALESCE(t_etages.oid,0) <> 0 THEN t_etages.texte ELSE w_lieux_c.etage_texte END etage_texte, w_lieux_c.lit_id, lit_code, lit_texte, CASE WHEN COALESCE(t_services_facturation.oid,0) <> 0 THEN t_services_facturation.code_original ELSE w_lieux_c.code_original_1 END AS code_original_1, code_original_2, CASE WHEN COALESCE(t_etages.oid,0) <> 0 THEN t_etages.code_original ELSE w_lieux_c.code_original_3 END AS code_original_3, code_original_4, code_original_5, code_original_6, code_original_7, gir_code_original, gir_id, gir_code, gir_texte, gir_coefficient FROM activite.p_sejours JOIN activite.t_sejour ON t_sejour.no_sejour = p_sejours.no_sejour JOIN w_lieux_c ON p_sejours.lieu_sortie_id = w_lieux_c.oid LEFT JOIN activite.t_services_facturation ON t_sejour.service_facturation_id = t_services_facturation.oid LEFT JOIN activite.t_etages ON t_sejour.etage_id = t_etages.oid WHERE est_ignore <> '1' AND ( t_sejour.service_facturation_id <> 0 OR t_sejour.etage_id <> 0 ) ; INSERT INTO w_lieux_c( oid, date_debut, date_fin, unite_medicale_id, unite_medicale_code, unite_medicale_texte, unite_fonctionnelle_id, unite_fonctionnelle_code, unite_fonctionnelle_texte, mode_traitement_id, mode_traitement_code, mode_traitement_texte, service_facturation_id, service_facturation_code, service_facturation_texte, type_t2a, service_facturation_est_sans_mouvement, service_facturation_est_absence, activite_id, activite_code, activite_texte, etage_id, etage_code, etage_texte, lit_id, lit_code, lit_texte, gir_code_original, gir_id, gir_code, gir_texte, gir_coefficient) SELECT w_lieux_c.oid, w_lieux_c.date_debut, w_lieux_c.date_fin, w_lieux_c.unite_medicale_id, w_lieux_c.unite_medicale_code, w_lieux_c.unite_medicale_texte, w_lieux_c.unite_fonctionnelle_id, w_lieux_c.unite_fonctionnelle_code, w_lieux_c.unite_fonctionnelle_texte, w_lieux_c.mode_traitement_id, w_lieux_c.mode_traitement_code, w_lieux_c.mode_traitement_texte, w_lieux_c.service_facturation_id, w_lieux_c.service_facturation_code, w_lieux_c.service_facturation_texte, w_lieux_c.type_t2a, w_lieux_c.service_facturation_est_sans_mouvement, w_lieux_c.service_facturation_est_absence, w_lieux_c.activite_id, w_lieux_c.activite_code, w_lieux_c.activite_texte, w_lieux_c.etage_id, w_lieux_c.etage_code, w_lieux_c.etage_texte, w_lieux_c.lit_id, w_lieux_c.lit_code, w_lieux_c.lit_texte, w_lieux_c.gir_code_original, w_lieux_c.gir_id, w_lieux_c.gir_code, w_lieux_c.gir_texte, w_lieux_c.gir_coefficient FROM w_lieux_new w_lieux_c LEFT JOIN activite.t_lieux_c ON t_lieux_c.oid = w_lieux_c.oid AND t_lieux_c.date_debut = w_lieux_c.date_debut AND t_lieux_c.date_fin = w_lieux_c.date_fin WHERE t_lieux_c.oid IS NULL; INSERT INTO activite.t_lieux( oid, code_original_1, code_original_2, code_original_3, code_original_4, code_original_5, code_original_6, code_original_7, service_facturation_id, activite_id, lit_id, unite_medicale_id, unite_fonctionnelle_id, mode_traitement_id, gir_code_original, gir_id) SELECT w_lieux_c.oid, w_lieux_c.code_original_1, w_lieux_c.code_original_2, w_lieux_c.code_original_3, w_lieux_c.code_original_4, w_lieux_c.code_original_5, w_lieux_c.code_original_6, w_lieux_c.code_original_7, w_lieux_c.service_facturation_id, w_lieux_c.activite_id, w_lieux_c.lit_id, w_lieux_c.unite_medicale_id, w_lieux_c.unite_fonctionnelle_id, w_lieux_c.mode_traitement_id, w_lieux_c.gir_code_original, w_lieux_c.gir_id FROM w_lieux_new as w_lieux_c left join activite.t_lieux on t_lieux.oid = w_lieux_c.oid WHERE t_lieux.oid is null ; UPDATE activite.p_sejours SET lieu_sortie_id = w_lieux_new.oid FROM w_lieux_new WHERE p_sejours.no_sejour = w_lieux_new.no_sejour; UPDATE activite.p_mouvements_sejour SET lieu_id = w_lieux_new.oid FROM w_lieux_new WHERE p_mouvements_sejour.no_sejour = w_lieux_new.no_sejour; UPDATE activite.p_factures_lignes_c SET lieu_id = w_lieux_new.oid FROM activite.p_factures JOIN w_lieux_new ON p_factures.no_sejour = w_lieux_new.no_sejour WHERE p_factures_lignes_c.no_facture = p_factures.no_facture; UPDATE activite.p_factures_lignes_h SET lieu_id = w_lieux_new.oid FROM activite.p_factures JOIN w_lieux_new ON p_factures.no_sejour = w_lieux_new.no_sejour WHERE p_factures_lignes_h.no_facture = p_factures.no_facture; UPDATE activite.p_sejours SET lieu_sortie_id = 0 WHERE lieu_sortie_id IS NULL; REINDEX TABLE activite.t_lieux; -- Etage affecté selon date DELETE FROM activite.t_lieux_c USING ( SELECT t_lieux_c.oid FROM activite.t_lieux_c LEFT JOIN w_lieux_c ON t_lieux_c.oid = w_lieux_c.oid AND t_lieux_c.date_debut = w_lieux_c.date_debut AND t_lieux_c.date_fin = w_lieux_c.date_fin WHERE w_lieux_c.oid IS NULL) subview WHERE t_lieux_c.oid = subview.oid; UPDATE activite.t_lieux_c SET unite_medicale_id = w_lieux_c.unite_medicale_id, unite_medicale_code = w_lieux_c.unite_medicale_code, unite_medicale_texte = w_lieux_c.unite_medicale_texte, unite_fonctionnelle_id = w_lieux_c.unite_fonctionnelle_id, unite_fonctionnelle_code = w_lieux_c.unite_fonctionnelle_code, unite_fonctionnelle_texte = w_lieux_c.unite_fonctionnelle_texte, mode_traitement_id = w_lieux_c.mode_traitement_id, mode_traitement_code = w_lieux_c.mode_traitement_code, mode_traitement_texte = w_lieux_c.mode_traitement_texte, service_facturation_id = w_lieux_c.service_facturation_id, service_facturation_code = w_lieux_c.service_facturation_code, service_facturation_texte = w_lieux_c.service_facturation_texte, type_t2a = w_lieux_c.type_t2a, service_facturation_est_sans_mouvement = w_lieux_c.service_facturation_est_sans_mouvement, service_facturation_est_absence = w_lieux_c.service_facturation_est_absence, activite_id = w_lieux_c.activite_id, activite_code = w_lieux_c.activite_code, activite_texte = w_lieux_c.activite_texte, etage_id = w_lieux_c.etage_id, etage_code = w_lieux_c.etage_code, etage_texte = w_lieux_c.etage_texte, lit_id = w_lieux_c.lit_id, lit_code = w_lieux_c.lit_code, lit_texte = w_lieux_c.lit_texte, gir_id = w_lieux_c.gir_id, gir_code = w_lieux_c.gir_code, gir_texte = w_lieux_c.gir_texte, gir_coefficient = w_lieux_c.gir_coefficient FROM w_lieux_c WHERE w_lieux_c.oid = t_lieux_c.oid AND w_lieux_c.date_debut = t_lieux_c.date_debut AND w_lieux_c.date_fin = t_lieux_c.date_fin AND ( t_lieux_c.unite_medicale_id IS DISTINCT FROM w_lieux_c.unite_medicale_id OR t_lieux_c.unite_medicale_code IS DISTINCT FROM w_lieux_c.unite_medicale_code OR t_lieux_c.unite_medicale_texte IS DISTINCT FROM w_lieux_c.unite_medicale_texte OR t_lieux_c.unite_fonctionnelle_id IS DISTINCT FROM w_lieux_c.unite_fonctionnelle_id OR t_lieux_c.unite_fonctionnelle_code IS DISTINCT FROM w_lieux_c.unite_fonctionnelle_code OR t_lieux_c.unite_fonctionnelle_texte IS DISTINCT FROM w_lieux_c.unite_fonctionnelle_texte OR t_lieux_c.mode_traitement_id IS DISTINCT FROM w_lieux_c.mode_traitement_id OR t_lieux_c.mode_traitement_code IS DISTINCT FROM w_lieux_c.mode_traitement_code OR t_lieux_c.mode_traitement_texte IS DISTINCT FROM w_lieux_c.mode_traitement_texte OR t_lieux_c.service_facturation_id IS DISTINCT FROM w_lieux_c.service_facturation_id OR t_lieux_c.service_facturation_code IS DISTINCT FROM w_lieux_c.service_facturation_code OR t_lieux_c.service_facturation_texte IS DISTINCT FROM w_lieux_c.service_facturation_texte OR t_lieux_c.type_t2a IS DISTINCT FROM w_lieux_c.type_t2a OR t_lieux_c.service_facturation_est_sans_mouvement IS DISTINCT FROM w_lieux_c.service_facturation_est_sans_mouvement OR t_lieux_c.service_facturation_est_absence IS DISTINCT FROM w_lieux_c.service_facturation_est_absence OR t_lieux_c.activite_id IS DISTINCT FROM w_lieux_c.activite_id OR t_lieux_c.activite_code IS DISTINCT FROM w_lieux_c.activite_code OR t_lieux_c.activite_texte IS DISTINCT FROM w_lieux_c.activite_texte OR t_lieux_c.etage_id IS DISTINCT FROM w_lieux_c.etage_id OR t_lieux_c.etage_code IS DISTINCT FROM w_lieux_c.etage_code OR t_lieux_c.etage_texte IS DISTINCT FROM w_lieux_c.etage_texte OR t_lieux_c.lit_id IS DISTINCT FROM w_lieux_c.lit_id OR t_lieux_c.lit_code IS DISTINCT FROM w_lieux_c.lit_code OR t_lieux_c.lit_texte IS DISTINCT FROM w_lieux_c.lit_texte OR t_lieux_c.gir_id IS DISTINCT FROM w_lieux_c.gir_id OR t_lieux_c.gir_code IS DISTINCT FROM w_lieux_c.gir_code OR t_lieux_c.gir_texte IS DISTINCT FROM w_lieux_c.gir_texte OR t_lieux_c.gir_coefficient IS DISTINCT FROM w_lieux_c.gir_coefficient ); INSERT INTO activite.t_lieux_c( oid, date_debut, date_fin, unite_medicale_id, unite_medicale_code, unite_medicale_texte, unite_fonctionnelle_id, unite_fonctionnelle_code, unite_fonctionnelle_texte, mode_traitement_id, mode_traitement_code, mode_traitement_texte, service_facturation_id, service_facturation_code, service_facturation_texte, type_t2a, service_facturation_est_sans_mouvement, service_facturation_est_absence, activite_id, activite_code, activite_texte, etage_id, etage_code, etage_texte, lit_id, lit_code, lit_texte, gir_id, gir_code, gir_texte, gir_coefficient) SELECT w_lieux_c.oid, w_lieux_c.date_debut, w_lieux_c.date_fin, w_lieux_c.unite_medicale_id, w_lieux_c.unite_medicale_code, w_lieux_c.unite_medicale_texte, w_lieux_c.unite_fonctionnelle_id, w_lieux_c.unite_fonctionnelle_code, w_lieux_c.unite_fonctionnelle_texte, w_lieux_c.mode_traitement_id, w_lieux_c.mode_traitement_code, w_lieux_c.mode_traitement_texte, w_lieux_c.service_facturation_id, w_lieux_c.service_facturation_code, w_lieux_c.service_facturation_texte, w_lieux_c.type_t2a, w_lieux_c.service_facturation_est_sans_mouvement, w_lieux_c.service_facturation_est_absence, w_lieux_c.activite_id, w_lieux_c.activite_code, w_lieux_c.activite_texte, w_lieux_c.etage_id, w_lieux_c.etage_code, w_lieux_c.etage_texte, w_lieux_c.lit_id, w_lieux_c.lit_code, w_lieux_c.lit_texte, w_lieux_c.gir_id, w_lieux_c.gir_code, w_lieux_c.gir_texte, w_lieux_c.gir_coefficient FROM w_lieux_c LEFT JOIN activite.t_lieux_c ON t_lieux_c.oid = w_lieux_c.oid AND t_lieux_c.date_debut = w_lieux_c.date_debut AND t_lieux_c.date_fin = w_lieux_c.date_fin WHERE t_lieux_c.oid IS NULL; -- Ajout Lieux créés par changement de date lit INSERT INTO activite.t_lieux( oid, code_original_1, code_original_2, code_original_3, code_original_4, code_original_5, code_original_6, code_original_7, service_facturation_id, activite_id, lit_id, unite_medicale_id, unite_fonctionnelle_id, mode_traitement_id, gir_code_original, gir_id) SELECT w_lieux_c.oid, w_lieux_c.code_original_1, w_lieux_c.code_original_2, w_lieux_c.code_original_3, w_lieux_c.code_original_4, w_lieux_c.code_original_5, w_lieux_c.code_original_6, w_lieux_c.code_original_7, w_lieux_c.service_facturation_id, w_lieux_c.activite_id, w_lieux_c.lit_id, w_lieux_c.unite_medicale_id, w_lieux_c.unite_fonctionnelle_id, w_lieux_c.mode_traitement_id, w_lieux_c.gir_code_original, w_lieux_c.gir_id FROM w_lieux_c left join activite.t_lieux on t_lieux.oid = w_lieux_c.oid WHERE t_lieux.oid is null ; -- Mise à jour des lieux dans les tables UPDATE activite.p_sejours SET lieu_sortie_id = w_lieux_c.oid FROM w_lieux_c WHERE p_sejours.lieu_sortie_id = w_lieux_c.from_oid AND w_lieux_c.oid <> w_lieux_c.from_oid AND p_sejours.date_sortie BETWEEN w_lieux_c.date_debut AND w_lieux_c.date_fin; UPDATE activite.p_mouvements_sejour SET lieu_id = w_lieux_c.oid FROM w_lieux_c WHERE p_mouvements_sejour.lieu_id = w_lieux_c.from_oid AND w_lieux_c.oid <> w_lieux_c.from_oid AND p_mouvements_sejour.date BETWEEN w_lieux_c.date_debut AND w_lieux_c.date_fin; UPDATE activite.p_factures_lignes_c SET lieu_id = w_lieux_c.oid FROM w_lieux_c WHERE p_factures_lignes_c.lieu_id = w_lieux_c.from_oid AND w_lieux_c.oid <> w_lieux_c.from_oid AND p_factures_lignes_c.date_debut BETWEEN w_lieux_c.date_debut AND w_lieux_c.date_fin; UPDATE activite.p_factures_encours_lignes_c SET lieu_id = w_lieux_c.oid FROM w_lieux_c WHERE p_factures_encours_lignes_c.lieu_id = w_lieux_c.from_oid AND w_lieux_c.oid <> w_lieux_c.from_oid AND p_factures_encours_lignes_c.date_debut BETWEEN w_lieux_c.date_debut AND w_lieux_c.date_fin; UPDATE activite.p_factures_lignes_h SET lieu_id = w_lieux_c.oid FROM w_lieux_c WHERE p_factures_lignes_h.lieu_id = w_lieux_c.from_oid AND w_lieux_c.oid <> w_lieux_c.from_oid AND p_factures_lignes_h.date_debut BETWEEN w_lieux_c.date_debut AND w_lieux_c.date_fin; -- Types de séjour INSERT INTO activite.t_type_sejour (oid, code, texte) SELECT base.cti_to_number(type_sejour), type_sejour, CASE WHEN p_sejours.type_sejour = '1'::bpchar THEN 'Hospitalisé'::bpchar WHEN p_sejours.type_sejour = '2'::bpchar THEN 'Ambulatoires'::bpchar WHEN p_sejours.type_sejour = '3'::bpchar THEN 'Externes'::bpchar WHEN p_sejours.type_sejour = '4'::bpchar THEN 'Long séjours'::bpchar WHEN p_sejours.type_sejour = '5'::bpchar THEN 'Séances'::bpchar WHEN p_sejours.type_sejour = '6'::bpchar THEN 'Bébés sans séjour'::bpchar WHEN p_sejours.type_sejour = '9'::bpchar THEN 'Fictifs'::bpchar ELSE p_sejours.type_sejour END AS texte FROM activite.p_sejours WHERE type_sejour NOT IN (SELECT code FROM activite.t_type_sejour) GROUP BY 1,2,3; -- Si etage modifié, l'inclure dans les oids INSERT INTO activite.p_oids (code_table, oid) SELECT 'etage', etage_id FROM activite.t_lieux_c WHERE etage_id NOT IN (SELECT oid FROM activite.p_oids WHERE code_table = 'etage') GROUP BY 2; -- Classes PERFORM base.cti_update_classes('activite', 't_lieux_c', 'SERVICE_F','service_facturation_section'); PERFORM base.cti_update_classes('activite', 't_lieux_c', 'ETAGE','etage_section'); PERFORM base.cti_update_classes('activite', 't_lieux_c', 'LIT','lit_section'); PERFORM base.cti_update_classes('activite', 't_lieux_c', 'UM','unite_medicale_section'); PERFORM base.cti_update_classes('activite', 't_lieux_c', 'UF','unite_fonctionnelle_section'); PERFORM base.cti_update_classes('activite', 't_lieux_c', 'ACTIVITE','activite_section'); PERFORM base.cti_update_classes('activite', 't_etages', 'ETAGE',''); PERFORM base.cti_update_classes('activite', 't_unites_fonctionnelles', 'UF',''); PERFORM base.cti_update_classes('activite', 't_type_sejour', 'TYPESEJOUR',''); PERFORM activite.cti_reorganize_places(); RETURN 'OK'; END;