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.
 
 

966 lines
36 KiB

return: text
lang: plpgsql
src: |
DECLARE
_module_pmsimco 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 = '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 = 'activite.p_sejour_pmsi' AND
column_name = 'ssr_id') THEN
ALTER TABLE activite.p_sejour_pmsi ADD COLUMN ssr_id bigint DEFAULT 0;
END IF;
IF NOT EXISTS (
SELECT column_name
FROM information_schema.columns
WHERE table_schema || '.' || table_name = 'activite.p_sejour_pmsi' AND
column_name = 'ssr_id_array') THEN
ALTER TABLE activite.p_sejour_pmsi ADD COLUMN ssr_id_array bigint[] ;
END IF;
IF NOT EXISTS (
SELECT column_name
FROM information_schema.columns
WHERE table_schema || '.' || table_name = 'activite.p_sejour_pmsi' AND
column_name = 'en_cours_pmsi') THEN
ALTER TABLE activite.p_sejour_pmsi ADD COLUMN en_cours_pmsi text;
END IF;
IF NOT EXISTS (
SELECT column_name
FROM information_schema.columns
WHERE table_schema || '.' || table_name = 'activite.p_sejour_pmsi' AND
column_name = 'traitement_epmsi') THEN
ALTER TABLE activite.p_sejour_pmsi ADD COLUMN traitement_epmsi text;
END IF;
IF NOT EXISTS (SELECT * FROM pg_class WHERE relnamespace = pg_my_temp_schema() AND relname = 'w_rss_rsp') THEN
CREATE TEMP TABLE w_rss_rsp
(
rss_id bigint,
no_rss bigint,
etat text,
matricule_assure text,
date_naissance date,
sexe text,
no_sejour_pmsi text,
date_entree date,
date_sortie date,
ghm_code text,
prestation_code text,
traitement_epmsi text,
en_cours_pmsi text,
no_sejour_activite text,
no_sejour_activite_reel text
) ;
CREATE INDEX w_rss_rsp_i1
ON w_rss_rsp
USING btree
(no_sejour_activite);
CREATE INDEX w_rss_rsp_i2
ON w_rss_rsp
USING btree
(no_sejour_pmsi);
CREATE INDEX w_rss_rsp_i3
ON w_rss_rsp
USING btree
(rss_id);
CREATE INDEX w_rss_rsp_i4
ON w_rss_rsp
USING btree
(no_sejour_activite_reel);
CREATE INDEX w_rss_rsp_i5
ON w_rss_rsp
USING btree
(traitement_epmsi);
CREATE INDEX w_rss_rsp_i6
ON w_rss_rsp
USING btree
(en_cours_pmsi);
END IF;
TRUNCATE activite.p_sejour_pmsi;
TRUNCATE w_rss_rsp;
-- Creation association rss pmsi mco - sejour activite
IF _module_pmsimco = '1' THEN
BEGIN
-- Pour les externes, il faut mettre en accord les dates sejours avec dates des actes
-- (special public rafael)
UPDATE pmsi.p_rss
SET date_entree = subview.date_debut
FROM
(
SELECT rss_id, p_rss.no_rss, no_sejour_administratif,
MAX(date_entree),
MAX(date_sortie),
MIN(p_rsf_detail.date_debut) AS date_debut,
MAX(p_rsf_detail.date_fin)
FROM pmsi.p_rsf_detail
JOIN pmsi.p_rss ON rss_id = p_rss.oid
JOIN base.t_finess ON t_finess.code = p_rss.finess AND type_etablissement <> '1'
WHERE p_rss.en_cours = '0' AND
p_rss.etat = '' AND
p_rss.ghm_id = 0
GROUP BY 1,2,3
HAVING MAX(date_entree) <> MIN(p_rsf_detail.date_debut) AND MIN(p_rsf_detail.date_debut) <= MAX(date_sortie)
) subview
WHERE p_rss.oid = subview.rss_id
;
INSERT INTO w_rss_rsp
SELECT p_rss.oid AS rss_id,
p_rss.no_rss,
p_rss.etat,
p_rsf_total.matricule_assure,
p_rss.date_naissance,
p_rss.sexe,
no_sejour_administratif AS no_sejour_pmsi,
p_rss.date_entree,
p_rss.date_sortie,
t_ghm.code AS ghm_code,
t_prestations.code AS prestation_code,
p_rss.traitement_epmsi,
p_rss.en_cours,
MAX(no_sejour) AS no_sejour_activite,
MAX(no_sejour) AS no_sejour_activite_reel
FROM pmsi.p_rss
LEFT JOIN pmsi.p_rsf_total ON p_rss.oid = p_rsf_total.rss_id
JOIN pmsi.t_ghm ON p_rss.ghm_id = t_ghm.oid
JOIN pmsi.t_prestations ON p_rss.prestation_principale_id = t_prestations.oid
JOIN activite.p_sejours ON no_sejour_administratif = no_sejour AND
(p_rss.date_entree BETWEEN p_sejours.date_entree AND p_sejours.date_sortie AND p_sejours.date_sortie <> '20991231' OR
p_rss.date_sortie BETWEEN p_sejours.date_entree AND p_sejours.date_sortie AND p_sejours.date_sortie <> '20991231' OR
p_rss.date_entree = p_sejours.date_entree)
WHERE p_rss.etat = ''
GROUP BY 1,2,3,4,5,6,7,8,9,10,11,12,13;
INSERT INTO w_rss_rsp
SELECT p_rss.oid AS rss_id,
p_rss.no_rss,
p_rss.etat,
p_rsf_total.matricule_assure,
p_rss.date_naissance,
p_rss.sexe,
no_sejour_administratif AS no_sejour_pmsi,
p_rss.date_entree,
p_rss.date_sortie,
t_ghm.code AS ghm_code,
t_prestations.code AS prestation_code,
p_rss.traitement_epmsi,
p_rss.en_cours,
MAX(no_sejour) AS no_sejour_activite,
MAX(no_sejour) AS no_sejour_activite_reel
FROM pmsi.p_rss
LEFT JOIN pmsi.p_rsf_total ON p_rss.oid = p_rsf_total.rss_id
JOIN pmsi.t_ghm ON p_rss.ghm_id = t_ghm.oid
JOIN pmsi.t_prestations ON p_rss.prestation_principale_id = t_prestations.oid
JOIN activite.p_sejours ON (substr(no_sejour_administratif,2,7) = no_sejour AND length(no_sejour) = 7) AND
(p_rss.date_entree BETWEEN p_sejours.date_entree AND p_sejours.date_sortie AND p_sejours.date_sortie <> '20991231' OR
p_rss.date_sortie BETWEEN p_sejours.date_entree AND p_sejours.date_sortie AND p_sejours.date_sortie <> '20991231' OR
p_rss.date_entree = p_sejours.date_entree)
WHERE p_rss.etat = ''
GROUP BY 1,2,3,4,5,6,7,8,9,10,11,12,13;
INSERT INTO w_rss_rsp
SELECT p_rss.oid AS rss_id,
p_rss.no_rss,
p_rss.etat,
p_rsf_total.matricule_assure,
p_rss.date_naissance,
p_rss.sexe,
no_sejour_administratif AS no_sejour_pmsi,
p_rss.date_entree,
p_rss.date_sortie,
t_ghm.code AS ghm_code,
t_prestations.code AS prestation_code,
p_rss.traitement_epmsi,
p_rss.en_cours,
NULL AS no_sejour_activite,
NULL AS no_sejour_activite_reel
FROM pmsi.p_rss
LEFT JOIN pmsi.p_rsf_total ON p_rss.oid = p_rsf_total.rss_id
JOIN pmsi.t_ghm ON p_rss.ghm_id = t_ghm.oid
JOIN pmsi.t_prestations ON p_rss.prestation_principale_id = t_prestations.oid
WHERE p_rss.etat = '' AND p_rss.oid NOT IN (SELECT rss_id FROM w_rss_rsp)
GROUP BY 1,2,3,4,5,6,7,8,9,10,11,12,13;
-- Special CERNER avec les externes avec sejours multiples
UPDATE w_rss_rsp SET
no_sejour_activite = subview.no_sejour,
no_sejour_activite_reel = subview.no_sejour
FROM
(
SELECT w_rss_rsp.rss_id, count(distinct p_sejours.no_sejour) , max(p_sejours.no_sejour) AS no_sejour
FROM w_rss_rsp
JOIN activite.p_sejours ON no_sejour_pmsi = split_part(p_sejours.no_sejour,'.',1)
WHERE no_sejour_activite is null AND
date(w_rss_rsp.date_entree) = date(p_sejours.date_entree) AND
date(w_rss_rsp.date_sortie) = date(p_sejours.date_sortie) AND
p_sejours.no_sejour NOT IN (SELECT no_sejour_activite FROM w_rss_rsp WHERE no_sejour_activite IS NOT NULL)
GROUP BY 1
HAVING count(distinct p_sejours.no_sejour) = 1
) subview
WHERE w_rss_rsp.rss_id = subview.rss_id
;
UPDATE w_rss_rsp SET
no_sejour_activite = subview.no_sejour,
no_sejour_activite_reel = subview.no_sejour
FROM
(
SELECT w_rss_rsp.rss_id, count(distinct p_sejours.no_sejour) , max(p_sejours.no_sejour) AS no_sejour
FROM w_rss_rsp
JOIN activite.p_sejours ON no_sejour_pmsi = split_part(p_sejours.no_sejour,'.',1)
WHERE no_sejour_activite is null AND
date(w_rss_rsp.date_sortie) = date(p_sejours.date_sortie) AND
p_sejours.no_sejour NOT IN (SELECT no_sejour_activite FROM w_rss_rsp WHERE no_sejour_activite IS NOT NULL)
GROUP BY 1
HAVING count(distinct p_sejours.no_sejour) = 1
) subview
WHERE w_rss_rsp.rss_id = subview.rss_id
;
UPDATE w_rss_rsp SET
no_sejour_activite = subview.no_sejour,
no_sejour_activite_reel = subview.no_sejour
FROM
(
SELECT w_rss_rsp.rss_id, count(distinct p_sejours.no_sejour) , max(p_sejours.no_sejour) AS no_sejour
FROM w_rss_rsp
JOIN activite.p_sejours ON no_sejour_pmsi = split_part(p_sejours.no_sejour,'.',1)
WHERE no_sejour_activite is null AND
date(p_sejours.date_entree) BETWEEN date(w_rss_rsp.date_entree) AND date(w_rss_rsp.date_sortie) AND
date(p_sejours.date_sortie) BETWEEN date(w_rss_rsp.date_entree) AND date(w_rss_rsp.date_sortie) AND
p_sejours.no_sejour NOT IN (SELECT no_sejour_activite FROM w_rss_rsp WHERE no_sejour_activite IS NOT NULL)
GROUP BY 1
HAVING count(distinct p_sejours.no_sejour) = 1
) subview
WHERE w_rss_rsp.rss_id = subview.rss_id
;
UPDATE w_rss_rsp SET
no_sejour_activite = subview.no_sejour,
no_sejour_activite_reel = subview.no_sejour
FROM
(
SELECT w_rss_rsp.rss_id, count(distinct p_sejours.no_sejour) , max(p_sejours.no_sejour) AS no_sejour
FROM w_rss_rsp
JOIN activite.p_sejours ON no_sejour_pmsi = split_part(p_sejours.no_sejour,'.',1)
WHERE no_sejour_activite is null AND
date(p_sejours.date_sortie) BETWEEN date(w_rss_rsp.date_entree) AND date(w_rss_rsp.date_sortie) AND
p_sejours.no_sejour NOT IN (SELECT no_sejour_activite FROM w_rss_rsp WHERE no_sejour_activite IS NOT NULL)
GROUP BY 1
) subview
WHERE w_rss_rsp.rss_id = subview.rss_id
;
DROP TABLE IF EXISTS w_doublons;
CREATE TEMP TABLE w_doublons AS
SELECT date_entree, date_sortie, date_naissance, sexe
FROM w_rss_rsp
GROUP BY 1,2,3,4
HAVING count(*) > 1;
UPDATE w_rss_rsp
SET no_sejour_activite = subview.no_sejour, no_sejour_activite_reel = subview.no_sejour_reel
FROM
(SELECT w_rss_rsp.rss_id,
MAX(CASE WHEN provider_id = 0 OR (provider_id = 2 AND (code is null OR code = 'LOGHOS')) THEN no_sejour ELSE substr(no_sejour,4) END) AS no_sejour,
MAX(no_sejour) AS no_sejour_reel
FROM w_rss_rsp, activite.p_sejours LEFT JOIN activite.t_providers ON provider_id = t_providers.oid
WHERE no_sejour_activite IS NULL AND
p_sejours.date_sortie = w_rss_rsp.date_sortie AND
p_sejours.no_sejour LIKE '%' || no_sejour_pmsi
GROUP BY 1
HAVING count(DISTINCT no_sejour) = 1) subview
WHERE w_rss_rsp.rss_id = subview.rss_id;
WITH fullSejours AS (
SELECT
p_sejours.no_sejour,
p_sejours.date_sortie,
p_sejours.date_entree,
p_patients.date_naissance,
p_patients.code_sexe,
t_providers.code,
p_sejours.provider_id
FROM activite.p_sejours
JOIN activite.p_patients ON p_sejours.no_patient = p_patients.no_patient
LEFT JOIN activite.t_providers ON provider_id = t_providers.oid
)
UPDATE w_rss_rsp
SET no_sejour_activite = subview.no_sejour, no_sejour_activite_reel = subview.no_sejour_reel
FROM
(SELECT w_rss_rsp.rss_id, no_sejour_pmsi,
MAX(CASE WHEN provider_id = 0 OR (provider_id = 2 AND (code is null OR code = 'LOGHOS')) THEN no_sejour ELSE substr(no_sejour,4) END) AS no_sejour,
MAX(no_sejour) AS no_sejour_reel
FROM w_rss_rsp
LEFT JOIN w_doublons ON
w_doublons.date_entree = w_rss_rsp.date_entree AND
w_doublons.date_sortie = w_rss_rsp.date_sortie AND
w_doublons.date_naissance = w_rss_rsp.date_naissance AND
w_doublons.sexe = w_rss_rsp.sexe
JOIN fullSejours ON
fullSejours.date_entree = w_rss_rsp.date_entree AND
fullSejours.date_sortie = w_rss_rsp.date_sortie AND
fullSejours.date_naissance = w_rss_rsp.date_naissance AND
fullSejours.code_sexe = w_rss_rsp.sexe
WHERE no_sejour_activite IS NULL
AND w_doublons IS NULL
GROUP BY 1,2
HAVING count(DISTINCT no_sejour) = 1) subview
WHERE w_rss_rsp.rss_id = subview.rss_id;
UPDATE w_rss_rsp
SET no_sejour_activite = subview.no_sejour_activite, no_sejour_activite_reel = subview.no_sejour_activite_reel
FROM
(SELECT w_rss_rsp.rss_id,
MAX(w_rss_rsp_mere.no_sejour_activite) AS no_sejour_activite,
MAX(w_rss_rsp_mere.no_sejour_activite_reel) AS no_sejour_activite_reel
FROM w_rss_rsp
JOIN w_rss_rsp w_rss_rsp_mere ON w_rss_rsp.matricule_assure = w_rss_rsp_mere.matricule_assure AND
w_rss_rsp.rss_id <> w_rss_rsp_mere.rss_id
WHERE w_rss_rsp.matricule_assure <> '' AND
(substr(w_rss_rsp.ghm_code,1,2) = '15' OR w_rss_rsp.ghm_code IN ('24Z23Z', '24Z24Z')) AND
(substr(w_rss_rsp_mere.ghm_code,1,2) = '14' OR w_rss_rsp_mere.ghm_code IN ('24Z20Z')) AND
w_rss_rsp.no_sejour_activite IS NULL AND
w_rss_rsp.date_entree BETWEEN w_rss_rsp_mere.date_entree AND w_rss_rsp_mere.date_sortie
GROUP BY 1
HAVING count(DISTINCT w_rss_rsp_mere.no_sejour_activite) = 1) subview
WHERE w_rss_rsp.rss_id = subview.rss_id;
UPDATE w_rss_rsp
SET no_sejour_activite = subviewa.no_sejour, no_sejour_activite_reel = subviewa.no_sejour_reel
FROM
(SELECT prestation_code, date_sortie, MAX(rss_id) AS rss_id
FROM w_rss_rsp
WHERE no_sejour_activite is null
GROUP BY 1,2
HAVING count(*) = 1) subviewp,
(SELECT t_prestations.code AS prestation_code,
p_sejours.date_sortie,
MAX(CASE WHEN p_sejours.provider_id = 0 OR (p_sejours.provider_id = 2 AND (t_providers.code is null OR t_providers.code = 'LOGHOS')) THEN p_sejours.no_sejour ELSE substr(p_sejours.no_sejour,4) END) AS no_sejour,
MAX(p_sejours.no_sejour) AS no_sejour_reel
FROM activite.p_sejours LEFT JOIN activite.t_providers ON provider_id = t_providers.oid
JOIN activite.p_factures ON p_factures.no_sejour = p_sejours.no_sejour AND p_factures.no_facture_reference = p_factures.no_facture
JOIN activite.p_factures_lignes_c ON p_factures_lignes_c.no_facture = p_factures.no_facture
JOIN activite.t_prestations ON prestation_id = t_prestations.oid
LEFT JOIN w_rss_rsp ON p_sejours.no_sejour = no_sejour_activite_reel
WHERE p_sejours.code_sorti = '1' AND
p_factures.date_facture <> '20991231' AND
w_rss_rsp.rss_id IS NULL AND
t_prestations.code IN ('SE1', 'SE2', 'SE3', 'SE4', 'FFM', 'ATU', 'FPU', 'GHS')
GROUP BY 1,2
HAVING count(DISTINCT p_sejours.no_sejour) = 1
ORDER BY 1,2) subviewa
WHERE subviewa.prestation_code = subviewp.prestation_code AND
subviewa.date_sortie = subviewp.date_sortie AND
w_rss_rsp.rss_id = subviewp.rss_id;
UPDATE w_rss_rsp
SET no_sejour_activite = subview.no_sejour
FROM
(SELECT rss_id, MAX(no_sejour) AS no_sejour
FROM w_rss_rsp, activite.p_factures
WHERE no_sejour_activite IS NULL AND
p_factures.date_fin = w_rss_rsp.date_sortie AND
p_factures.no_facture LIKE '%' || no_sejour_pmsi
GROUP BY 1
HAVING count(DISTINCT no_sejour) = 1
) subview
WHERE w_rss_rsp.rss_id = subview.rss_id;
UPDATE w_rss_rsp
SET no_sejour_activite = subview.no_sejour, no_sejour_activite_reel = subview.no_sejour
FROM
(
SELECT w_rss_rsp.rss_id, count(distinct p_sejours.no_sejour) , max(p_sejours.no_sejour) AS no_sejour
FROM w_rss_rsp
JOIN activite.p_sejours ON no_sejour_pmsi = p_sejours.no_sejour
JOIN activite.p_patients On p_patients.no_patient = p_sejours.no_patient
WHERE no_sejour_activite is null AND
date_trunc('year',p_sejours.date_sortie) = date_trunc('year',w_rss_rsp.date_sortie) AND
w_rss_rsp.ghm_code LIKE '28%' AND
p_patients.date_naissance = w_rss_rsp.date_naissance
GROUP BY 1
) subview
WHERE w_rss_rsp.rss_id = subview.rss_id
;
UPDATE w_rss_rsp
SET no_sejour_activite = subview.no_sejour, no_sejour_activite_reel = subview.no_sejour
FROM
(
SELECT w_rss_rsp.rss_id,
MAX(no_sejour) AS no_sejour,
MAX(no_sejour) AS no_sejour_reel
FROM w_rss_rsp, activite.p_sejours
WHERE no_sejour_activite IS NULL AND
date_trunc('month',p_sejours.date_sortie) = date_trunc('month',w_rss_rsp.date_sortie) AND
p_sejours.no_sejour LIKE '%' || no_sejour_pmsi
GROUP BY 1
HAVING count(DISTINCT no_sejour) = 1
) subview
WHERE w_rss_rsp.rss_id = subview.rss_id
;
UPDATE pmsi.p_rss
SET no_sejour_administratif = w_rss_rsp.no_sejour_activite
FROM w_rss_rsp
WHERE w_rss_rsp.rss_id = p_rss.oid AND
no_sejour_administratif IS DISTINCT FROM w_rss_rsp.no_sejour_activite AND
w_rss_rsp.no_sejour_activite IS NOT NULL;
INSERT INTO activite.p_sejour_pmsi (
sejour_id,
no_sejour,
pmsi_type,
rss_id,
no_rss,
traitement_epmsi,
en_cours_pmsi
)
SELECT p_sejours.oid AS sejour_id,
p_sejours.no_sejour AS no_sejour,
'MCO' AS pmsi_type,
w_rss_rsp.rss_id,
w_rss_rsp.no_rss,
w_rss_rsp.traitement_epmsi,
w_rss_rsp.en_cours_pmsi
FROM activite.p_sejours
JOIN w_rss_rsp ON p_sejours.no_sejour = no_sejour_activite_reel
WHERE w_rss_rsp.no_sejour_activite_reel IS NOT NULL;
--EXCEPTION
--WHEN others THEN RAISE NOTICE 'Erreur %' , 'PMSI MCO';
END;
END IF;
-- Sejours activite sans PMSi
BEGIN
INSERT INTO activite.p_sejour_pmsi (
sejour_id,
no_sejour,
pmsi_type,
rss_id,
no_rss
)
SELECT p_sejours.oid AS sejour_id,
p_sejours.no_sejour AS no_sejour,
'' AS pmsi_type,
0,
0
FROM activite.p_sejours
WHERE no_sejour NOT IN (SELECT no_sejour FROM activite.p_sejour_pmsi);
EXCEPTION
WHEN others THEN RAISE NOTICE 'Erreur %' , 'FIN';
END;
-- Mise e jour des medecins PMSI MCO / Activite
IF _module_pmsimco = '1' THEN
BEGIN
INSERT INTO activite.t_divers (code, texte, valeur, description, valeur2)
SELECT
'PMSIMEDECIN',
'Replication medecins Activite/PMSI',
'0',
'0=Pas de replication, 1=Remplacemet medecin PMSI par medecin Activite',
''
WHERE 'PMSIMEDECIN' NOT IN (SELECT code FROM activite.t_divers);
IF EXISTS (SELECT * FROM activite.t_divers WHERE code = 'PMSIMEDECIN' AND valeur = '1') THEN
IF NOT EXISTS (SELECT * FROM pg_class WHERE relnamespace = pg_my_temp_schema() AND relname = 'w_dif') THEN
CREATE TEMP TABLE w_dif (
rss_id bigint,
no_rss bigint,
pmsi_medecin_id bigint,
pmsi_medecin_pmsi_id bigint,
no_sejour text,
adm_medecin_id bigint
);
END IF;
IF NOT EXISTS (SELECT * FROM pg_class WHERE relnamespace = pg_my_temp_schema() AND relname = 'w_adm_medecin') THEN
CREATE TEMP TABLE w_adm_medecin (
adm_medecin_id bigint
);
END IF;
IF NOT EXISTS (SELECT * FROM pg_class WHERE relnamespace = pg_my_temp_schema() AND relname = 'w_adm_medecin_pmsi') THEN
CREATE TEMP TABLE w_adm_medecin_pmsi (
adm_medecin_id bigint,
pmsi_oid bigint
);
END IF;
TRUNCATE w_dif;
TRUNCATE w_adm_medecin;
TRUNCATE w_adm_medecin_pmsi;
INSERT INTO w_dif
SELECT
p_rss.oid AS rss_id,
p_rss.no_rss,
t_medecins_pmsi.medecin_id AS pmsi_medecin_id,
t_medecins_pmsi.oid AS pmsi_medecin_pmsi_id,
p_sejours.no_sejour,
t_medecins_administratifs.medecin_id AS adm_medecin_id
FROM activite.p_sejour_pmsi
JOIN activite.p_sejours ON p_sejour_pmsi.no_sejour = p_sejours.no_sejour
JOIN pmsi.p_rss ON p_sejour_pmsi.rss_id = p_rss.oid
LEFT JOIN activite.t_medecins_administratifs ON medecin_sejour_id = t_medecins_administratifs.oid
LEFT JOIN pmsi.t_medecins t_medecins_pmsi ON p_rss.medecin_rss_id = t_medecins_pmsi.oid
WHERE pmsi_type = 'MCO' AND
t_medecins_administratifs.medecin_id <> 0 AND
t_medecins_pmsi.medecin_id IS DISTINCT FROM t_medecins_administratifs.medecin_id;
INSERT INTO w_adm_medecin
SELECT adm_medecin_id
FROM w_dif
GROUP BY 1;
INSERT INTO w_adm_medecin_pmsi
SELECT adm_medecin_id, (MAX(Array[date_sortie::text,pmsi_oid::text]))[2]::bigint AS pmsi_oid
FROM (
SELECT adm_medecin_id, t_medecins_pmsi.oid AS pmsi_oid, MAX(COALESCE(date_sortie,'00010101')) AS date_sortie
FROM w_adm_medecin
JOIN pmsi.t_medecins t_medecins_pmsi ON adm_medecin_id = t_medecins_pmsi.medecin_id
JOIN pmsi.p_rss ON t_medecins_pmsi.oid = p_rss.medecin_rss_id
GROUP BY 1,2
ORDER BY 1,2,3 DESC
) subview
GROUP BY 1;
INSERT INTO w_adm_medecin_pmsi
SELECT adm_medecin_id, (MAX(Array[date_sortie::text,pmsi_oid::text]))[2]::bigint AS pmsi_oid
FROM (
SELECT adm_medecin_id, t_medecins_pmsi.oid AS pmsi_oid, MAX(COALESCE(date_acte,'00010101')) AS date_sortie
FROM w_adm_medecin
JOIN pmsi.t_medecins t_medecins_pmsi ON adm_medecin_id = t_medecins_pmsi.medecin_id
JOIN pmsi.p_rss_actes ON t_medecins_pmsi.oid = p_rss_actes.medecin_id
WHERE adm_medecin_id NOT IN (SELECT adm_medecin_id FROM w_adm_medecin_pmsi)
GROUP BY 1,2
ORDER BY 1,2,3 DESC
) subview
GROUP BY 1;
INSERT INTO pmsi.t_medecins(
code,
nom,
prenom,
specialite_id,
no_adeli,
statut,
medecin_reference_id,
specialite_interne_id,
identifiant_annuaire,
medecin_id)
SELECT
t_medecins.code,
t_medecins.nom,
t_medecins.prenom,
0,
'',
'',
0,
0,
'',
adm_medecin_id
FROM w_adm_medecin
JOIN base.t_medecins ON adm_medecin_id = t_medecins.oid
WHERE adm_medecin_id NOT IN (SELECT adm_medecin_id FROM w_adm_medecin_pmsi) AND
code NOT IN (SELECT code FROM pmsi.t_medecins);
INSERT INTO w_adm_medecin_pmsi
SELECT adm_medecin_id, MAX(pmsi_oid) AS pmsi_oid
FROM (
SELECT adm_medecin_id, t_medecins_pmsi.oid AS pmsi_oid
FROM w_adm_medecin
JOIN pmsi.t_medecins t_medecins_pmsi ON adm_medecin_id = t_medecins_pmsi.medecin_id
WHERE adm_medecin_id NOT IN (SELECT adm_medecin_id FROM w_adm_medecin_pmsi)
GROUP BY 1,2
) subview
GROUP BY 1;
PERFORM pmsi.cti_reorganize_medecins_c();
UPDATE pmsi.p_rss
SET medecin_rss_id = pmsi_oid
FROM w_dif
JOIN w_adm_medecin_pmsi ON w_dif.adm_medecin_id = w_adm_medecin_pmsi.adm_medecin_id
WHERE p_rss.oid = w_dif.rss_id AND pmsi_medecin_pmsi_id = medecin_rss_id;
END IF;
EXCEPTION
WHEN others THEN RAISE NOTICE 'Erreur %' , 'FIN';
END;
END IF;
-- Mise e jour des associations provenant du SSR
IF _module_pmsissr = '1' THEN
-- Tables dans base
INSERT INTO base.t_gn (code, texte)
SELECT code, texte
FROM pmsissr.t_gn
WHERE oid <> 0 AND code NOT IN (SELECT code FROM base.t_gn)
;
INSERT INTO base.t_cm (code, texte)
SELECT code, texte
FROM pmsissr.t_cm
WHERE oid <> 0 AND code NOT IN (SELECT code FROM base.t_cm)
;
INSERT INTO base.t_rgme (code, texte)
SELECT code, texte
FROM pmsissr.t_rgme
WHERE oid <> 0 AND code NOT IN (SELECT code FROM base.t_rgme)
;
INSERT INTO base.t_gme (code, texte)
SELECT code, texte
FROM pmsissr.t_gme
WHERE oid <> 0 AND code NOT IN (SELECT code FROM base.t_gme)
;
UPDATE base.t_gme t_gme_base
SET gn_id = t_gn_base.oid
FROm pmsissr.t_gme
JOIN pmsissr.t_gn ON t_gme.gn_id = t_gn.oid
JOIN base.t_gn t_gn_base ON t_gn_base.code = t_gn.code
WHERE t_gme_base.code = t_gme.code AND
t_gme_base.gn_id IS DISTINCT FROM t_gn_base.oid
;
UPDATE base.t_gme t_gme_base
SET cm_id = t_cm_base.oid
FROm pmsissr.t_gme
JOIN pmsissr.t_cm ON t_gme.cm_id = t_cm.oid
JOIN base.t_cm t_cm_base ON t_cm_base.code = t_cm.code
WHERE t_gme_base.code = t_gme.code AND
t_gme_base.cm_id IS DISTINCT FROM t_cm_base.oid
;
UPDATE base.t_gme t_gme_base
SET rgme_id = t_rgme_base.oid
FROm pmsissr.t_gme
JOIN pmsissr.t_rgme ON t_gme.rgme_id = t_rgme.oid
JOIN base.t_rgme t_rgme_base ON t_rgme_base.code = t_rgme.code
WHERE t_gme_base.code = t_gme.code AND
t_gme_base.rgme_id IS DISTINCT FROM t_rgme_base.oid
;
DROP TABLE IF EXISTS w_ssr;
CREATE TEMP TABLE w_ssr AS
SELECT oid,
trim(num_admin_sejour ) AS num_admin_sejour ,
CASE
WHEN substr(p_ssr.num_admin_sejour,1,1) = '0' THEN ltrim(trim(p_ssr.num_admin_sejour),'0')
WHEN substr(p_ssr.num_admin_sejour,1,1) BETWEEN 'A' AND 'Z' THEN trim(substr(p_ssr.num_admin_sejour,2))
ELSE NULL END AS num_admin_sejour_2,
p_ssr.date_sortie,
''::text AS no_sejour,
0::bigint AS sejour_id
FROM pmsissr.p_ssr;
ANALYSE w_ssr
;
CREATE INDEX w_ssr_i1
ON w_ssr
USING btree
(num_admin_sejour);
CREATE INDEX w_ssr_i2
ON w_ssr
USING btree
(num_admin_sejour_2);
DROP TABLE IF EXISTS w_sejours;
CREATE TEMP TABLE w_sejours AS
SELECT oid,
trim(no_sejour) AS no_sejour,
trim(no_sejour) AS no_sejour_secondaire,
trim(CASE WHEN substr(p_sejours.no_sejour,1) BETWEEN 'A' AND 'Z' THEN substr(no_sejour,2) ELSE NULL END) AS no_sejour_hm,
trim(CASE WHEN substr(p_sejours.no_sejour,1) BETWEEN 'A' AND 'Z' AND substr(no_sejour,3,1) = '_' THEN substr(no_sejour,4) ELSE NULL END) AS no_sejour_anterieur,
p_sejours.date_sortie,
NULL::text[] AS no_sejours_dependants
FROM activite.p_sejours;
ANALYSE w_sejours
;
CREATE INDEX w_sejours_i1
ON w_sejours
USING btree
(no_sejour);
INSERT INTO w_sejours
SELECT w_sejours.oid,
w_sejours.no_sejour,
split_part(no_facture,'.',1) AS no_sejour_secondaire,
NULL::text AS no_sejour_hm,
trim(CASE WHEN substr(split_part(no_facture,'.',1),1) BETWEEN 'A' AND 'Z' AND substr(split_part(no_facture,'.',1),3,1) = '_' THEN substr(split_part(no_facture,'.',1),4) ELSE NULL END) AS no_sejour_anterieur
FROM w_sejours
JOIN activite.p_factures ON p_factures.no_sejour = w_sejours.no_sejour
WHERE no_facture LIKE '%.00' AND
split_part(no_facture,'.',1) <> w_sejours.no_sejour AND
trim(CASE WHEN substr(split_part(no_facture,'.',1),1) BETWEEN 'A' AND 'Z' AND substr(split_part(no_facture,'.',1),3,1) = '_' THEN substr(split_part(no_facture,'.',1),4) ELSE NULL END) <> w_sejours.no_sejour
;
UPDATE w_ssr
SET no_sejour = w_sejours.no_sejour, sejour_id = w_sejours.oid
FROM w_sejours
WHERE
w_sejours.no_sejour_secondaire = w_ssr.num_admin_sejour OR
w_sejours.no_sejour_hm = w_ssr.num_admin_sejour OR
w_sejours.no_sejour_anterieur = w_ssr.num_admin_sejour
;
UPDATE w_ssr
SET no_sejour = w_sejours.no_sejour, sejour_id = w_sejours.oid
FROM w_sejours
WHERE
w_sejours.no_sejour_secondaire = w_ssr.num_admin_sejour_2 OR
w_sejours.no_sejour_hm = w_ssr.num_admin_sejour_2 OR
w_sejours.no_sejour_anterieur = w_ssr.num_admin_sejour_2
;
UPDATE activite.p_sejour_pmsi SET
ssr_id = subview.ssr_id,
ssr_id_array = subview.ssr_id_array,
pmsi_type = 'SSR'
FROM
(
SELECT no_sejour,
MAX(oid) AS ssr_id,
base.cti_array_accum(oid) As ssr_id_array ,
count(*)
FROM w_ssr
GROUP BY 1
) subview
WHERE p_sejour_pmsi.no_sejour = subview.no_sejour
;
-- Récupération des gme provenant des lots
UPDATE activite.p_sejours
SET gme_id = subview.gme_id
FROM
(
SELECT p_sejour_pmsi.no_sejour, t_gme_base.oid AS gme_id
FROM pmsissr.p_ssr
JOIN activite.p_sejour_pmsi ON p_sejour_pmsi.ssr_id = p_ssr.oid AND p_ssr.oid <> 0
JOIN pmsissr.t_gme On gme_id = t_gme.oid
JOIN base.t_gme t_gme_base ON t_gme.code = t_gme_base.code
) subview
WHERE p_sejours.no_sejour = subview.no_sejour AND
p_sejours.gme_id IS DISTINCT FROM subview.gme_id
;
-- Récupération des gme provenant du fil de l'eau
-- On prend le GME de la dernière semaine des séjours
UPDATE activite.p_sejours
SET gme_id = subview.gme_id
FROM
(
SELECT ssr_id, p_rhs_fil_eau.gme_id,p_ssr_fil_eau.num_admin_sejour, ROW_NUMBER() OVER (PARTITION BY ssr_id ORDER BY rang DESC) AS rn
FROM pmsissr.p_rhs_fil_eau
JOIN pmsissr.p_ssr_fil_eau ON ssr_id = p_ssr_fil_eau.oid
LEFT JOIN pmsissr.p_ssr ON p_ssr_fil_eau.num_admin_sejour = p_ssr.num_admin_sejour
WHERE p_ssr.num_admin_sejour IS NULL
) subview
WHERE subview.num_admin_sejour = p_sejours.no_sejour
AND subview.rn = 1
AND p_sejours.gme_id IS DISTINCT FROM subview.gme_id
;
-- Hors SSR. Divers
UPDATE activite.p_sejours
SET gme_id = -9990
FROM activite.t_lieux
JOIN activite.t_services_facturation ON service_facturation_id = t_services_facturation.oid
JOIN activite.t_gme_c ON t_gme_c.gme_id = -9990
WHERE lieu_sortie_id = t_lieux.oid AND
p_sejours.gme_id = 0 AND
type_t2a NOT IN ('1','2')
;
-- Hors SSR. MCO
UPDATE activite.p_sejours
SET gme_id = -9991
FROM activite.t_lieux
JOIN activite.t_services_facturation ON service_facturation_id = t_services_facturation.oid
JOIN activite.t_gme_c ON t_gme_c.gme_id = -9991
WHERE lieu_sortie_id = t_lieux.oid AND
p_sejours.gme_id = 0 AND
type_t2a = '1'
;
-- Champ SSR. Présents
UPDATE activite.p_sejours
SET gme_id = -9980
FROM activite.t_lieux
JOIN activite.t_services_facturation ON service_facturation_id = t_services_facturation.oid
JOIN activite.t_gme_c ON t_gme_c.gme_id = -9980
WHERE lieu_sortie_id = t_lieux.oid AND
p_sejours.gme_id = 0 AND
type_t2a = '2' AND
code_sorti <> '1'
;
-- Champ SSR. Sortis non groupés
UPDATE activite.p_sejours
SET gme_id = -9981
FROM activite.t_lieux
JOIN activite.t_services_facturation ON service_facturation_id = t_services_facturation.oid
JOIN activite.t_gme_c ON t_gme_c.gme_id = -9981
WHERE lieu_sortie_id = t_lieux.oid AND
p_sejours.gme_id = 0 AND
type_t2a = '2' AND
code_sorti = '1'
;
-- Calcul du délai de groupage
UPDATE activite.p_sejours
SET delai_groupage = date_groupage - date_sortie
WHERE code_sorti = '1' AND
date_groupage > date_sortie AND
date_groupage < '2099-12-31' AND
gme_id > 0
;
END IF;
-- Mise e jour des modes entree sortie selon pmsi ssr
IF _module_pmsissr = '1' THEN
UPDATE activite.p_sejours SET
mode_entree = p_ssr.mode_entree,
provenance = CASE WHEN p_ssr.provenance <> '' THEN p_ssr.provenance ELSE '0' END
FROM pmsissr.p_ssr
WHERE p_sejours.no_sejour = p_ssr.num_admin_sejour AND
p_ssr.mode_entree <> '' AND
(
p_sejours.mode_entree IS DISTINCT FROM p_ssr.mode_entree OR
p_sejours.provenance IS DISTINCT FROM CASE WHEN p_ssr.provenance <> '' THEN p_ssr.provenance ELSE '0' END
)
;
UPDATE activite.p_sejours SET
mode_sortie = p_ssr.mode_sortie,
destination = CASE WHEN p_ssr.destination <> '' THEN p_ssr.destination ELSE '0' END
FROM pmsissr.p_ssr
WHERE p_sejours.no_sejour = p_ssr.num_admin_sejour AND
p_sejours.code_sorti = '1' AND
p_ssr.mode_sortie <> '' AND
(
p_sejours.mode_sortie IS DISTINCT FROM p_ssr.mode_sortie OR
p_sejours.destination IS DISTINCT FROM CASE WHEN p_ssr.destination <> '' THEN p_ssr.destination ELSE '0' END
)
;
-- Mise à jour Nom dans PMSI SSR (si pas fait par import SSR
UPDATE pmsissr.p_patients SET
nom = subview.nom,
prenom = subview.prenom,
num_patient = subview.no_patient
FROM
(
SELECT p_patients.oid, p_patients_a.nom, p_patients_a.prenom, p_patients_a.nom_naissance, base.cti_to_number(p_patients_a.no_patient) AS no_patient
FROM pmsissr.p_patients
JOIN pmsissr.p_ssr ON p_ssr.patient_id = p_patients.oid
JOIN activite.p_sejour_pmsi ON p_ssr.oid = p_sejour_pmsi.ssr_id
JOIN activite.p_sejours ON p_sejour_pmsi.sejour_id = p_sejours.oid
JOIN activite.p_patients p_patients_a ON p_patients_a.no_patient = p_sejours.no_patient
WHERE p_patients.date_naissance = p_patients_a.date_naissance AND
p_patients.nom ilike '%non rens%'
) subview
WHERE p_patients.oid = subview.oid
;
END IF ;
-- Mise e jour matricule assure depuis pmsi mco
IF _module_pmsimco = '1' THEN
DROP TABLE IF EXISTS w_sejour_assurance;
CREATE TEMP TABLE w_sejour_assurance AS
SELECT
p_sejours.oid AS sejour_id,
tiers_payant_0_id, tiers_payant_1_id, tiers_payant_2_id, tiers_payant_22_id,
MAX(p_rsf_total.matricule_assure) AS matricule_assure
FROM activite.p_sejours
JOIN activite.p_sejour_pmsi ON p_sejours.oid = p_sejour_pmsi.sejour_id
JOIN pmsi.p_rsf_total ON p_sejour_pmsi.rss_id = p_rsf_total.rss_id
WHERE p_rsf_total.matricule_assure <> '' AND
substr(p_rsf_total.matricule_assure,1,5) <> '00000' AND
length(p_rsf_total.matricule_assure) = 13
GROUP BY 1,2,3,4,5
;
UPDATE activite.p_sejours_assurance
SET matricule_1 = w_sejour_assurance.matricule_assure
FROM w_sejour_assurance
WHERE w_sejour_assurance.sejour_id = p_sejours_assurance.sejour_id AND
w_sejour_assurance.matricule_assure IS DISTINCT FROM p_sejours_assurance.matricule_1 AND
w_sejour_assurance.matricule_assure IS DISTINCT FROM substr(p_sejours_assurance.matricule_1,1,13) AND
p_sejours_assurance.matricule_1 = ''
;
INSERT INTO activite.p_sejours_assurance(
sejour_id,
tiers_payant_0_id, tiers_payant_1_id, tiers_payant_2_id, tiers_payant_22_id,
matricule_1, matricule_2, matricule_22)
SELECT
sejour_id,
tiers_payant_0_id, tiers_payant_1_id, tiers_payant_2_id, tiers_payant_22_id,
matricule_assure, '', ''
FROM w_sejour_assurance
WHERE sejour_id NOT IN (SELECT sejour_id FROM activite.p_sejours_assurance)
;
END IF;
-- Mise e jour matricule assure depuis pmsi ssr
IF _module_pmsissr = '1' THEN
DROP TABLE IF EXISTS w_sejour_assurance;
CREATE TEMP TABLE w_sejour_assurance AS
SELECT
p_sejours.oid AS sejour_id,
tiers_payant_0_id, tiers_payant_1_id, tiers_payant_2_id, tiers_payant_22_id,
MAX(to_char(p_ssr.numero_matricule,'FM0000000000000')) AS matricule_assure
FROM activite.p_sejours
JOIN activite.p_sejour_pmsi ON p_sejours.oid = p_sejour_pmsi.sejour_id
JOIN pmsissr.p_ssr ON p_sejour_pmsi.ssr_id = p_ssr.oid
WHERE p_ssr.numero_matricule <> 0
GROUP BY 1,2,3,4,5
;
UPDATE activite.p_sejours_assurance
SET matricule_1 = w_sejour_assurance.matricule_assure
FROM w_sejour_assurance
WHERE w_sejour_assurance.sejour_id = p_sejours_assurance.sejour_id AND
w_sejour_assurance.matricule_assure IS DISTINCT FROM p_sejours_assurance.matricule_1 AND
w_sejour_assurance.matricule_assure IS DISTINCT FROM substr(p_sejours_assurance.matricule_1,1,13) AND
p_sejours_assurance.matricule_1 = ''
;
INSERT INTO activite.p_sejours_assurance(
sejour_id,
tiers_payant_0_id, tiers_payant_1_id, tiers_payant_2_id, tiers_payant_22_id,
matricule_1, matricule_2, matricule_22)
SELECT
sejour_id,
tiers_payant_0_id, tiers_payant_1_id, tiers_payant_2_id, tiers_payant_22_id,
matricule_assure, '', ''
FROM w_sejour_assurance
WHERE sejour_id NOT IN (SELECT sejour_id FROM activite.p_sejours_assurance)
;
END IF;
RETURN 'OK';
END;