return: text
|
|
lang: plpgsql
|
|
src: |
|
|
DECLARE
|
|
_module_pmsimco TEXT;
|
|
_module_activite TEXT;
|
|
_module_pmsissr TEXT;
|
|
result TEXT;
|
|
BEGIN
|
|
IF EXISTS (SELECT * FROM pg_tables WHERE schemaname = 'pmsi' AND tablename = 'p_rss') THEN
|
|
_module_pmsimco = '1';
|
|
ELSE
|
|
_module_pmsimco = '0';
|
|
END IF;
|
|
|
|
IF EXISTS (SELECT * FROM pg_tables WHERE schemaname = 'activite' AND tablename = 'p_sejours') THEN
|
|
_module_activite = '1';
|
|
ELSE
|
|
_module_activite = '0';
|
|
END IF;
|
|
IF EXISTS (SELECT * FROM pg_tables WHERE schemaname = 'pmsissr' AND tablename = 'p_ssr') THEN
|
|
_module_pmsissr = '1';
|
|
ELSE
|
|
_module_pmsissr = '0';
|
|
END IF;
|
|
|
|
|
|
IF NOT EXISTS (
|
|
SELECT column_name
|
|
FROM information_schema.columns
|
|
WHERE table_schema || '.' || table_name = 'eco.p_sejours' AND
|
|
column_name = 'ssr_id') THEN
|
|
ALTER TABLE eco.p_sejours ADD COLUMN ssr_id bigint DEFAULT 0;
|
|
END IF;
|
|
|
|
IF NOT EXISTS (
|
|
SELECT column_name
|
|
FROM information_schema.columns
|
|
WHERE table_schema || '.' || table_name = 'eco.p_sejours' AND
|
|
column_name = 'ssr_id') THEN
|
|
ALTER TABLE eco.p_sejours ADD COLUMN ssr_id bigint DEFAULT 0;
|
|
END IF;
|
|
|
|
TRUNCATE eco.p_sejours;
|
|
|
|
-- Creation association eco - sejour pmsi
|
|
IF _module_pmsimco = '1' THEN
|
|
BEGIN
|
|
|
|
IF NOT EXISTS (
|
|
SELECT column_name
|
|
FROM information_schema.columns
|
|
WHERE 'pmsi.' || table_name = 'pmsi.p_rss_lpp' AND
|
|
column_name = 'from_eco') THEN
|
|
ALTER TABLE pmsi.p_rss_lpp ADD COLUMN from_eco bigint DEFAULT 0;
|
|
END IF;
|
|
|
|
IF NOT EXISTS (
|
|
SELECT column_name
|
|
FROM information_schema.columns
|
|
WHERE 'pmsi.' || table_name = 'pmsi.p_rss_ucd' AND
|
|
column_name = 'from_eco') THEN
|
|
ALTER TABLE pmsi.p_rss_ucd ADD COLUMN from_eco bigint DEFAULT 0;
|
|
END IF;
|
|
|
|
IF NOT EXISTS (
|
|
SELECT column_name
|
|
FROM information_schema.columns
|
|
WHERE 'pmsi.' || table_name = 'pmsi.p_rss_lpp' AND
|
|
column_name = 'montant_consommation') THEN
|
|
ALTER TABLE pmsi.p_rss_lpp ADD COLUMN montant_consommation numeric DEFAULT 0;
|
|
END IF;
|
|
|
|
IF NOT EXISTS (
|
|
SELECT column_name
|
|
FROM information_schema.columns
|
|
WHERE 'pmsi.' || table_name = 'pmsi.p_rss_ucd' AND
|
|
column_name = 'montant_consommation') THEN
|
|
ALTER TABLE pmsi.p_rss_ucd ADD COLUMN montant_consommation numeric DEFAULT 0;
|
|
END IF;
|
|
|
|
IF NOT EXISTS (
|
|
SELECT column_name
|
|
FROM information_schema.columns
|
|
WHERE 'pmsi.' || table_name = 'pmsi.p_rss_lpp' AND
|
|
column_name = 'type_lpp_id') THEN
|
|
ALTER TABLE pmsi.p_rss_lpp ADD COLUMN type_lpp_id bigint DEFAULT 0;
|
|
END IF;
|
|
|
|
DROP TABLE IF EXISTS w_rss;
|
|
CREATE TEMP TABLE w_rss
|
|
(
|
|
mouvement_id bigint,
|
|
rss_id bigint,
|
|
no_sejour_pmsi text,
|
|
no_rss text,
|
|
date_entree date,
|
|
date_sortie date
|
|
) ;
|
|
CREATE INDEX w_rss_i1
|
|
ON w_rss
|
|
USING btree
|
|
(mouvement_id);
|
|
CREATE INDEX w_rss_i2
|
|
ON w_rss
|
|
USING btree
|
|
(no_sejour_pmsi);
|
|
CREATE INDEX w_rss_i3
|
|
ON w_rss
|
|
USING btree
|
|
(rss_id);
|
|
|
|
-- sejour + date
|
|
INSERT INTO w_rss
|
|
SELECT p_mouvements_articles.oid AS mouvement_id,
|
|
p_rss.oid AS rss_id,
|
|
p_rss.no_sejour_administratif,
|
|
p_rss.no_rss,
|
|
p_rss.date_entree,
|
|
p_rss.date_sortie
|
|
FROM eco.p_mouvements_articles
|
|
JOIN pmsi.p_rss ON no_sejour_administratif = no_sejour
|
|
AND no_sejour_administratif != ''
|
|
AND p_mouvements_articles.date BETWEEN date_entree AND date_sortie
|
|
WHERE p_rss.etat = ''
|
|
;
|
|
|
|
-- sejour + patient + première date
|
|
INSERT INTO w_rss
|
|
SELECT p_mouvements_articles.oid AS mouvement_id,
|
|
sub.rss_id,
|
|
p_rss.no_sejour_administratif,
|
|
p_rss.no_rss,
|
|
p_rss.date_entree,
|
|
p_rss.date_sortie
|
|
FROM eco.p_mouvements_articles
|
|
LEFT JOIN w_rss ON oid = mouvement_id
|
|
JOIN (SELECT p_mouvements_articles.oid,
|
|
(MIN(ARRAY[abs(date - date_entree)::text,p_rss.oid::text]))[2]::bigint AS rss_id
|
|
FROM eco.p_mouvements_articles JOIN pmsi.p_rss ON no_sejour_administratif = no_sejour
|
|
AND p_rss.no_patient = p_mouvements_articles.no_patient
|
|
WHERE p_rss.etat = '' AND p_mouvements_articles.oid NOT IN (SELECT mouvement_id FROM w_rss)
|
|
GROUP BY 1) sub ON sub.oid = p_mouvements_articles.oid
|
|
JOIN pmsi.p_rss ON sub.rss_id = p_rss.oid
|
|
WHERE mouvement_id IS NULL
|
|
;
|
|
|
|
-- no patient avec dates correspondantes
|
|
INSERT INTO w_rss
|
|
SELECT p_mouvements_articles.oid AS mouvement_id,
|
|
sub.rss_id,
|
|
p_rss.no_sejour_administratif,
|
|
p_rss.no_rss,
|
|
p_rss.date_entree,
|
|
p_rss.date_sortie
|
|
FROM eco.p_mouvements_articles
|
|
JOIN (SELECT p_mouvements_articles.oid,
|
|
(MIN(ARRAY[abs(date - date_entree)::text,p_rss.oid::text]))[2]::bigint AS rss_id
|
|
FROM eco.p_mouvements_articles JOIN pmsi.p_rss ON date BETWEEN p_rss.date_entree AND p_rss.date_sortie
|
|
AND p_rss.no_patient = p_mouvements_articles.no_patient
|
|
WHERE p_rss.etat = '' AND p_mouvements_articles.oid NOT IN (SELECT mouvement_id FROM w_rss)
|
|
GROUP BY 1) sub ON sub.oid = p_mouvements_articles.oid
|
|
JOIN pmsi.p_rss ON sub.rss_id = p_rss.oid
|
|
;
|
|
|
|
|
|
|
|
INSERT INTO eco.p_sejours (
|
|
mouvement_id,
|
|
rss_id,
|
|
no_sejour,
|
|
no_rss
|
|
)
|
|
SELECT mouvement_id,
|
|
rss_id,
|
|
no_sejour_pmsi,
|
|
no_rss
|
|
FROM w_rss
|
|
;
|
|
|
|
|
|
UPDATE eco.p_sejours
|
|
SET no_patient = p_rss.no_patient
|
|
FROM pmsi.p_rss
|
|
WHERE p_sejours.rss_id = p_rss.oid AND
|
|
p_sejours.no_patient IS DISTINCT FROM p_rss.no_patient
|
|
;
|
|
|
|
UPDATE eco.p_mouvements_articles
|
|
SET medecin_reference_id = t_medecins.medecin_id
|
|
FROM eco.p_sejours
|
|
JOIN pmsi.p_rss ON p_sejours.rss_id = p_rss.oid
|
|
JOIN pmsi.t_medecins ON medecin_rss_id = t_medecins.oid
|
|
WHERE mouvement_id = p_mouvements_articles.oid AND
|
|
p_mouvements_articles.medecin_reference_id IS DISTINCT FROM t_medecins.medecin_id
|
|
;
|
|
|
|
|
|
END;
|
|
END IF;
|
|
|
|
|
|
|
|
-- Mise e jour des associations provenant d'activité
|
|
IF _module_activite = '1' THEN
|
|
|
|
DROP TABLE IF EXISTS w_sejours;
|
|
CREATE TEMP TABLE w_sejours
|
|
(
|
|
mouvement_id bigint,
|
|
sejour_id bigint,
|
|
no_sejour_pmsi text,
|
|
date_entree date,
|
|
date_sortie date
|
|
) ;
|
|
CREATE INDEX w_sejours_i1
|
|
ON w_sejours
|
|
USING btree
|
|
(mouvement_id);
|
|
CREATE INDEX w_sejours_i2
|
|
ON w_sejours
|
|
USING btree
|
|
(no_sejour_pmsi);
|
|
CREATE INDEX w_sejours_i3
|
|
ON w_sejours
|
|
USING btree
|
|
(sejour_id);
|
|
|
|
-- sejour + patient + date
|
|
INSERT INTO w_sejours
|
|
SELECT p_mouvements_articles.oid AS mouvement_id,
|
|
p_sejours.oid AS sejour_id,
|
|
p_sejours.no_sejour,
|
|
p_sejours.date_entree,
|
|
p_sejours.date_sortie
|
|
FROM eco.p_mouvements_articles
|
|
JOIN activite.p_sejours ON p_sejours.no_sejour = p_mouvements_articles.no_sejour AND
|
|
p_mouvements_articles.date BETWEEN date_entree AND date_sortie
|
|
;
|
|
|
|
-- sejour + patient + première date
|
|
INSERT INTO w_sejours
|
|
SELECT p_mouvements_articles.oid AS mouvement_id,
|
|
sub.sejour_id,
|
|
p_sejours.no_sejour,
|
|
p_sejours.date_entree,
|
|
p_sejours.date_sortie
|
|
FROM eco.p_mouvements_articles
|
|
LEFT JOIN w_sejours ON oid = mouvement_id
|
|
JOIN (SELECT p_mouvements_articles.oid,
|
|
(MIN(ARRAY[abs(date - date_entree)::text,p_sejours.oid::text]))[2]::bigint AS sejour_id
|
|
FROM eco.p_mouvements_articles JOIN activite.p_sejours ON p_sejours.no_sejour = p_mouvements_articles.no_sejour
|
|
AND p_sejours.no_patient = p_mouvements_articles.no_patient
|
|
WHERE p_sejours.etat = '' AND p_mouvements_articles.oid NOT IN (SELECT mouvement_id FROM w_sejours)
|
|
GROUP BY 1) sub ON sub.oid = p_mouvements_articles.oid
|
|
JOIN activite.p_sejours ON sub.sejour_id = p_sejours.oid
|
|
WHERE mouvement_id IS NULL
|
|
;
|
|
|
|
-- no patient avec dates correspondantes
|
|
INSERT INTO w_sejours
|
|
SELECT p_mouvements_articles.oid AS mouvement_id,
|
|
sub.sejour_id,
|
|
p_sejours.no_sejour,
|
|
p_sejours.date_entree,
|
|
p_sejours.date_sortie
|
|
FROM eco.p_mouvements_articles
|
|
JOIN (SELECT p_mouvements_articles.oid,
|
|
(MIN(ARRAY[abs(date - date_entree)::text,p_sejours.oid::text]))[2]::bigint AS sejour_id
|
|
FROM eco.p_mouvements_articles JOIN activite.p_sejours ON date BETWEEN p_sejours.date_entree AND p_sejours.date_sortie
|
|
AND p_sejours.no_patient = p_mouvements_articles.no_patient
|
|
WHERE p_sejours.etat = '' AND p_mouvements_articles.oid NOT IN (SELECT mouvement_id FROM w_sejours)
|
|
GROUP BY 1) sub ON sub.oid = p_mouvements_articles.oid
|
|
JOIN activite.p_sejours ON sub.sejour_id = p_sejours.oid
|
|
;
|
|
|
|
UPDATE eco.p_sejours
|
|
SET
|
|
sejour_id = w_sejours.sejour_id
|
|
FROM
|
|
w_sejours
|
|
WHERE
|
|
p_sejours.mouvement_id = w_sejours.mouvement_id
|
|
;
|
|
|
|
INSERT INTO eco.p_sejours (mouvement_id, sejour_id, no_sejour)
|
|
SELECT mouvement_id, sejour_id , no_sejour_pmsi
|
|
FROM w_sejours
|
|
WHERE w_sejours.mouvement_id NOT IN (SELECT mouvement_id FROM eco.p_sejours)
|
|
;
|
|
|
|
UPDATE eco.p_sejours
|
|
SET
|
|
sejour_id = p_sejour_pmsi.sejour_id,
|
|
no_sejour = p_sejour_pmsi.no_sejour
|
|
FROM
|
|
activite.p_sejour_pmsi
|
|
WHERE
|
|
p_sejours.rss_id = p_sejour_pmsi.rss_id
|
|
AND p_sejours.sejour_id = 0
|
|
AND p_sejour_pmsi.sejour_id IS NOT NULL
|
|
;
|
|
|
|
|
|
UPDATE eco.p_sejours
|
|
SET
|
|
rss_id = p_sejour_pmsi.rss_id,
|
|
no_rss = p_sejour_pmsi.no_rss
|
|
FROM
|
|
activite.p_sejour_pmsi
|
|
WHERE
|
|
p_sejours.sejour_id = p_sejour_pmsi.sejour_id
|
|
AND p_sejours.rss_id = 0
|
|
AND p_sejour_pmsi.rss_id IS NOT NULL
|
|
;
|
|
|
|
UPDATE eco.p_sejours SET no_patient = sejours.no_patient
|
|
FROM
|
|
activite.p_sejours sejours
|
|
WHERE sejour_id = sejours.oid AND
|
|
p_sejours.no_patient IS DISTINCT FROM sejours.no_patient
|
|
;
|
|
|
|
UPDATE eco.p_mouvements_articles
|
|
SET medecin_reference_id = t_medecins_administratifs.medecin_id
|
|
FROM eco.p_sejours
|
|
JOIN activite.p_sejours p_sejours_activite ON p_sejours.sejour_id = p_sejours_activite.oid
|
|
JOIN activite.t_medecins_administratifs ON p_sejours_activite.medecin_sejour_id = t_medecins_administratifs.oid AND
|
|
t_medecins_administratifs.medecin_id <> 0
|
|
WHERE p_mouvements_articles.oid = p_sejours.mouvement_id
|
|
AND p_mouvements_articles.medecin_reference_id IS DISTINCT FROM t_medecins_administratifs.medecin_id
|
|
;
|
|
|
|
END IF;
|
|
|
|
-- Mise e jour des associations provenant du SSR
|
|
IF _module_pmsissr = '1' THEN
|
|
BEGIN
|
|
|
|
END;
|
|
|
|
END IF;
|
|
|
|
UPDATE eco.p_mouvements_articles
|
|
SET medecin_reference_id = 0
|
|
WHERE medecin_reference_id IS NULL
|
|
;
|
|
|
|
ANALYSE eco.p_sejours;
|
|
REINDEX TABLE eco.p_sejours;
|
|
|
|
RETURN 'OK';
|
|
END;
|