You can not select more than 25 topics Topics must start with a letter or number, can include dashes ('-') and can be up to 35 characters long.
 
 

267 lines
12 KiB

return: text
lang: plpgsql
src: |
DECLARE
BEGIN
IF NOT EXISTS (SELECT *FROM information_schema.columns WHERE table_name = 't_unites_medicales' AND table_schema = 'activite' AND column_name = 'type_eclatement') THEN
RETURN 'KO. Pas de colonne type_eclatement';
END IF;
PERFORM setval('activite.s_lieux', (SELECT COALESCE(MAX(oid),0) + 1 FROM activite.t_lieux), true);
-- Eclatement à la première um (cas des soins continus)
IF EXISTS (SELECT * FROM activite.t_unites_medicales WHERE type_eclatement = '1') THEN
RAISE NOTICE '%' , 'Ventilation premiere um. Recherche sejours';
DROP TABLE IF EXISTS w_transform_um_0;
CREATE TEMP TABLE w_transform_um_0 AS
SELECT no_sejour,
(MIN(CASE WHEN type_eclatement IS DISTINCT FROM '1' THEN ARRAY[to_char(date,'YYYYMMDD')::text||to_char(heure_debut,'FM000000'),unite_medicale_id::text] ELSE ARRAY['20991231999999'::text,'0'::text] END))[2]::bigint AS first_unite_medicale_id,
''::text AS first_unite_medicale_code,
''::text AS first_unite_medicale_texte
FROM activite.p_mouvements_sejour
JOIN activite.t_lieux ON lieu_id = t_lieux.oid
JOIN activite.t_unites_medicales ON unite_medicale_id = t_unites_medicales.oid
GROUP BY 1
HAVING SUM(CASE WHEN type_eclatement = '1' THEN 1 ELSE 0 END)>0
;
-- Au moins un séjour concerné
IF EXISTS (SELECT * FROM w_transform_um_0) THEN
UPDATE w_transform_um_0 SET
first_unite_medicale_code = t_unites_medicales.code,
first_unite_medicale_texte = t_unites_medicales.texte
FROM activite.t_unites_medicales
WHERE first_unite_medicale_id = t_unites_medicales.oid AND
first_unite_medicale_id <> 0;
UPDATE w_transform_um_0 SET
first_unite_medicale_code = 'MONO',
first_unite_medicale_texte = 'MonoRUM'
WHERE first_unite_medicale_id = 0;
RAISE NOTICE '%' , 'Ventilation premiere um. Recherche lieux';
DROP TABLE IF EXISTS w_transform_um_1;
CREATE TEMP TABLE w_transform_um_1 AS
SELECT p_mouvements_sejour.no_sejour,
lieu_id,
MAX(t_unites_medicales.code || '-' || first_unite_medicale_code) AS new_unite_medicale_code,
MAX(t_unites_medicales.texte || '-' || first_unite_medicale_texte) AS new_unite_medicale_texte,
MAX(service_facturation_id) AS service_facturation_id,
MAX(activite_id) AS activite_id,
MAX(lit_id) AS lit_id,
MAX(unite_medicale_id) AS unite_medicale_id,
MAX(unite_fonctionnelle_id) AS unite_fonctionnelle_id,
0::bigint AS new_unite_medicale_id,
0::bigint AS new_lieu_id
FROM activite.p_mouvements_sejour
JOIN w_transform_um_0 ON w_transform_um_0.no_sejour = p_mouvements_sejour.no_sejour
JOIN activite.t_lieux ON lieu_id = t_lieux.oid
JOIN activite.t_unites_medicales ON unite_medicale_id = t_unites_medicales.oid
WHERE type_eclatement = '1'
GROUP BY 1,2;
RAISE NOTICE '%' , 'Ventilation premiere um. Nouvelles um';
INSERT INTO activite.t_unites_medicales(code_original, code, texte, texte_court)
SELECT '*'||new_unite_medicale_code, new_unite_medicale_code, new_unite_medicale_texte, new_unite_medicale_texte
FROM w_transform_um_1
WHERE ('*'||new_unite_medicale_code) NOT IN (SELECT code_original FROM activite.t_unites_medicales)
GROUP BY 1,2,3,4
ORDER BY 1;
UPDATE w_transform_um_1
SET new_unite_medicale_id = t_unites_medicales.oid
FROM activite.t_unites_medicales
WHERE ('*'||new_unite_medicale_code) = code_original;
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
)
SELECT
nextval('activite.s_lieux'::regclass) AS oid,
subview.*
FROM
(
SELECT t_lieux.code_original_1,
t_lieux.code_original_2,
t_lieux.code_original_3,
t_lieux.code_original_4,
('*'||new_unite_medicale_code) AS code_original_5,
t_lieux.code_original_6,
t_lieux.code_original_7,
t_lieux.service_facturation_id,
t_lieux.activite_id,
t_lieux.lit_id,
new_unite_medicale_id AS unite_medicale_id,
t_lieux.unite_fonctionnelle_id,
t_lieux.mode_traitement_id
FROM activite.t_lieux
JOIN w_transform_um_1 ON t_lieux.oid = w_transform_um_1.lieu_id
LEFT JOIN activite.t_lieux t_lieux_deja ON
t_lieux.service_facturation_id = t_lieux_deja.service_facturation_id AND
t_lieux.activite_id = t_lieux_deja.activite_id AND
t_lieux.lit_id = t_lieux_deja.lit_id AND
t_lieux.unite_fonctionnelle_id = t_lieux_deja.unite_fonctionnelle_id AND
new_unite_medicale_id = t_lieux_deja.unite_medicale_id
WHERE t_lieux_deja.oid IS NULL
GROUP BY 1,2,3,4,5,6,7,8,9,10,11,12,13
) subview;
UPDATE w_transform_um_1
SET new_lieu_id = t_lieux.oid
FROM activite.t_lieux
WHERE t_lieux.service_facturation_id = w_transform_um_1.service_facturation_id AND
t_lieux.activite_id = w_transform_um_1.activite_id AND
t_lieux.lit_id = w_transform_um_1.lit_id AND
t_lieux.unite_fonctionnelle_id = w_transform_um_1.unite_fonctionnelle_id AND
t_lieux.unite_medicale_id = w_transform_um_1.new_unite_medicale_id;
RAISE NOTICE '%' , 'Ventilation premiere um. Modification sejours';
UPDATE activite.p_mouvements_sejour
SET lieu_id = new_lieu_id
FROM w_transform_um_1
WHERE w_transform_um_1.no_sejour = p_mouvements_sejour.no_sejour AND
w_transform_um_1.lieu_id = p_mouvements_sejour.lieu_id;
UPDATE activite.p_sejours
SET lieu_sortie_id = new_lieu_id
FROM w_transform_um_1
WHERE w_transform_um_1.no_sejour = p_sejours.no_sejour AND
w_transform_um_1.lieu_id = p_sejours.lieu_sortie_id;
UPDATE activite.p_factures_lignes_c
SET lieu_id = new_lieu_id
FROM w_transform_um_1
JOIN activite.p_factures on p_factures.no_sejour = w_transform_um_1.no_sejour
WHERE p_factures_lignes_c.no_facture = p_factures.no_facture AND
w_transform_um_1.lieu_id = p_factures_lignes_c.lieu_id;
UPDATE activite.p_factures_lignes_h
SET lieu_id = new_lieu_id
FROM w_transform_um_1
JOIN activite.p_factures on p_factures.no_sejour = w_transform_um_1.no_sejour
WHERE p_factures_lignes_h.no_facture = p_factures.no_facture AND
w_transform_um_1.lieu_id = p_factures_lignes_h.lieu_id;
END IF;
END IF;
-- Eclatement à la spécialité médecin (cas des externes)
IF EXISTS (SELECT * FROM activite.t_unites_medicales WHERE type_eclatement = '2') THEN
RAISE NOTICE '%' , 'Ventilation Specialite. Recherche sejours';
DROP TABLE IF EXISTS w_transform_um_2;
CREATE TEMP TABLE w_transform_um_2 AS
SELECT no_sejour,
lieu_id,
MAX(specialite_code) AS specialite_code,
MAX(replace(t_unites_medicales.code,'-MONO','') || '-' || replace(specialite_code,'.','')) AS new_unite_medicale_code,
MAX(replace(t_unites_medicales.texte,'-MonoRUM','') || '-' || specialite_texte) AS new_unite_medicale_texte,
MAX(service_facturation_id) AS service_facturation_id,
MAX(activite_id) AS activite_id,
MAX(lit_id) AS lit_id,
MAX(unite_medicale_id) AS unite_medicale_id,
MAX(unite_fonctionnelle_id) AS unite_fonctionnelle_id,
0::bigint AS new_unite_medicale_id,
0::bigint AS new_lieu_id
FROM activite.p_mouvements_sejour
JOIN activite.t_lieux ON lieu_id = t_lieux.oid
JOIN activite.t_unites_medicales ON unite_medicale_id = t_unites_medicales.oid
JOIN activite.t_medecins_administratifs_c ON medecin_sejour_id = t_medecins_administratifs_c.oid
WHERE type_eclatement = '2' AND specialite_id <> 0
GROUP BY 1,2;
-- Au moins un séjour concerné
IF EXISTS (SELECT * FROM w_transform_um_2) THEN
RAISE NOTICE '%' , 'Ventilation Specialite. Nouvelles um';
INSERT INTO activite.t_unites_medicales(code_original, code, texte, texte_court)
SELECT '*'||new_unite_medicale_code, new_unite_medicale_code, new_unite_medicale_texte, new_unite_medicale_texte
FROM w_transform_um_2
WHERE ('*'||new_unite_medicale_code) NOT IN (SELECT code_original FROM activite.t_unites_medicales)
GROUP BY 1,2,3,4
ORDER BY 1;
UPDATE w_transform_um_2
SET new_unite_medicale_id = t_unites_medicales.oid
FROM activite.t_unites_medicales
WHERE ('*'||new_unite_medicale_code) = code_original;
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
)
SELECT
nextval('activite.s_lieux'::regclass) AS oid,
subview.*
FROM
(
SELECT t_lieux.code_original_1,
t_lieux.code_original_2,
t_lieux.code_original_3,
t_lieux.code_original_4,
('*'||new_unite_medicale_code) AS code_original_5,
t_lieux.code_original_6,
t_lieux.code_original_7,
t_lieux.service_facturation_id,
t_lieux.activite_id,
t_lieux.lit_id,
new_unite_medicale_id AS unite_medicale_id,
t_lieux.unite_fonctionnelle_id,
t_lieux.mode_traitement_id
FROM activite.t_lieux
JOIN w_transform_um_2 ON t_lieux.oid = w_transform_um_2.lieu_id
LEFT JOIN activite.t_lieux t_lieux_deja ON
t_lieux.service_facturation_id = t_lieux_deja.service_facturation_id AND
t_lieux.activite_id = t_lieux_deja.activite_id AND
t_lieux.lit_id = t_lieux_deja.lit_id AND
t_lieux.unite_fonctionnelle_id = t_lieux_deja.unite_fonctionnelle_id AND
new_unite_medicale_id = t_lieux_deja.unite_medicale_id
WHERE t_lieux_deja.oid IS NULL
GROUP BY 1,2,3,4,5,6,7,8,9,10,11,12,13
) subview;
UPDATE w_transform_um_2
SET new_lieu_id = t_lieux.oid
FROM activite.t_lieux
WHERE t_lieux.service_facturation_id = w_transform_um_2.service_facturation_id AND
t_lieux.activite_id = w_transform_um_2.activite_id AND
t_lieux.lit_id = w_transform_um_2.lit_id AND
t_lieux.unite_fonctionnelle_id = w_transform_um_2.unite_fonctionnelle_id AND
t_lieux.unite_medicale_id = w_transform_um_2.new_unite_medicale_id;
RAISE NOTICE '%' , 'Ventilation Specialite. Modification séjours';
UPDATE activite.p_mouvements_sejour
SET lieu_id = new_lieu_id
FROM w_transform_um_2
WHERE w_transform_um_2.no_sejour = p_mouvements_sejour.no_sejour AND
w_transform_um_2.lieu_id = p_mouvements_sejour.lieu_id;
UPDATE activite.p_sejours
SET lieu_sortie_id = new_lieu_id
FROM w_transform_um_2
WHERE w_transform_um_2.no_sejour = p_sejours.no_sejour AND
w_transform_um_2.lieu_id = p_sejours.lieu_sortie_id;
UPDATE activite.p_factures_lignes_c
SET lieu_id = new_lieu_id
FROM w_transform_um_2
JOIN activite.p_factures on p_factures.no_sejour = w_transform_um_2.no_sejour
WHERE p_factures_lignes_c.no_facture = p_factures.no_facture AND
w_transform_um_2.lieu_id = p_factures_lignes_c.lieu_id;
UPDATE activite.p_factures_lignes_h
SET lieu_id = new_lieu_id
FROM w_transform_um_2
JOIN activite.p_factures on p_factures.no_sejour = w_transform_um_2.no_sejour
WHERE p_factures_lignes_h.no_facture = p_factures.no_facture AND
w_transform_um_2.lieu_id = p_factures_lignes_h.lieu_id;
END IF;
END IF;
RETURN 'OK';
END;