|
|
<?xml version="1.0" encoding="ISO-8859-1"?>
|
|
|
<ROOT>
|
|
|
|
|
|
<NODE name="PMSICOMPLEMENTS" label="RECUPERATION DES DONNEES COMPLEMENTAIRES PMSI">
|
|
|
|
|
|
<NODE label="Paramètres">
|
|
|
<sqlcmd><![CDATA[
|
|
|
|
|
|
-- Spécialités médecin
|
|
|
INSERT INTO pmsi.t_specialites_medecin(code, texte)
|
|
|
SELECT ELT_C_COD, MAX(ELT_L_LNG)
|
|
|
FROM prod_mipih_noyau.cvno_elt
|
|
|
WHERE NOM_C_COD = 'CVG_QUAL' AND
|
|
|
ELT_C_COD NOT IN (SELECT code FROM pmsi.t_specialites_medecin)
|
|
|
GROUP BY 1
|
|
|
ORDER BY 1;
|
|
|
|
|
|
INSERT INTO pmsi.t_specialites_internes_medecin(code, texte)
|
|
|
SELECT
|
|
|
code || '..',
|
|
|
texte
|
|
|
FROM pmsi.t_specialites_medecin
|
|
|
WHERE oid <> 0 AND
|
|
|
(code || '..') NOT IN (SELECT code FROM pmsi.t_specialites_internes_medecin);
|
|
|
|
|
|
-- Médecins
|
|
|
INSERT INTO pmsi.t_medecins(code, nom, prenom, specialite_id, no_adeli, specialite_interne_id)
|
|
|
SELECT MD_IDAN, MD_NOM, MD_PRN,
|
|
|
COALESCE(t_specialites_medecin.oid,0),
|
|
|
MD_NOOR,
|
|
|
COALESCE(t_specialites_internes_medecin.oid,0)
|
|
|
FROM prod_mipih_noyau.CV_MD
|
|
|
LEFT JOIN pmsi.t_specialites_medecin ON MD_QLCD_ELT_COD = t_specialites_medecin.code
|
|
|
LEFT JOIN pmsi.t_specialites_internes_medecin ON (MD_QLCD_ELT_COD || '..') = t_specialites_internes_medecin.code
|
|
|
WHERE MD_IDAN IN (SELECT ACT_CDMED FROM prod_mipih_noyau.DA_ACT) AND
|
|
|
MD_IDAN NOT IN (SELECT code FROM pmsi.t_medecins);
|
|
|
|
|
|
UPDATE pmsi.t_medecins SET
|
|
|
nom = MD_NOM,
|
|
|
prenom = MD_PRN,
|
|
|
specialite_id = COALESCE(t_specialites_medecin.oid,0)
|
|
|
FROM prod_mipih_noyau.CV_MD
|
|
|
LEFT JOIN pmsi.t_specialites_medecin ON MD_QLCD_ELT_COD = t_specialites_medecin.code
|
|
|
WHERE t_medecins.code = MD_IDAN AND
|
|
|
(
|
|
|
nom <> MD_NOM OR
|
|
|
prenom <> MD_PRN OR
|
|
|
specialite_id <> COALESCE(t_specialites_medecin.oid,0)
|
|
|
);
|
|
|
|
|
|
|
|
|
-- Unités médicales
|
|
|
DROP TABLE IF EXISTS w_CV_UF;
|
|
|
CREATE TEMP TABLE w_CV_UF AS
|
|
|
SELECT UF_CODE,
|
|
|
(MAX(ARRAY[UF_DATDEB::text, UF_LIBEL]))[2] AS UF_LIBEL,
|
|
|
CASE WHEN UF_CODE IN (SELECT DOS_DERUFM FROM prod_mipih_noyau.DA_DOSADM JOIN [SCHEMA].p_rss ON no_sejour_administratif = DOS_IEP) THEN '1' ELSE '0' END AS UF_USED
|
|
|
FROM prod_mipih_noyau.CV_UF
|
|
|
GROUP BY 1
|
|
|
ORDER BY 1;
|
|
|
|
|
|
|
|
|
UPDATE pmsi.t_unites_medicales
|
|
|
SET texte = UF_LIBEL
|
|
|
FROM w_CV_UF
|
|
|
WHERE UF_CODE = t_unites_medicales.code AND
|
|
|
texte <> UF_LIBEL;
|
|
|
|
|
|
|
|
|
INSERT INTO pmsi.t_unites_medicales (code, texte)
|
|
|
SELECT
|
|
|
UF_CODE,
|
|
|
UF_LIBEL
|
|
|
FROM w_CV_UF
|
|
|
WHERE UF_USED = '1' AND
|
|
|
UF_CODE NOT IN (SELECT code FROM pmsi.t_unites_medicales WHERE code IS NOT NULL)
|
|
|
;
|
|
|
|
|
|
|
|
|
]]></sqlcmd>
|
|
|
</NODE>
|
|
|
|
|
|
<NODE label="Identités et Médecin RSS">
|
|
|
<sqlcmd><![CDATA[
|
|
|
|
|
|
-- n° patient
|
|
|
UPDATE [SCHEMA].p_rss SET
|
|
|
no_patient = base.cti_to_number(DA_DOSADM.PAT_IPP)
|
|
|
FROM prod_mipih_noyau.DA_DOSADM
|
|
|
JOIN prod_mipih_noyau.PA_PAT ON DA_DOSADM.PAT_IPP = PA_PAT.PAT_IPP
|
|
|
WHERE no_sejour_administratif = DOS_IEP AND
|
|
|
date_naissance = date(ETC_DDN) AND
|
|
|
(
|
|
|
no_patient <> base.cti_to_number(DA_DOSADM.PAT_IPP)
|
|
|
);
|
|
|
|
|
|
-- nom
|
|
|
UPDATE [SCHEMA].p_identites SET
|
|
|
nom = CASE WHEN ETC_NOM_MAR <> '' THEN ETC_NOM_MAR ELSE ETC_NOM END,
|
|
|
nom_naissance = CASE WHEN ETC_NOM_MAR <> '' THEN ETC_NOM ELSE '' END,
|
|
|
prenom = ETC_PRN
|
|
|
FROM [SCHEMA].p_rss
|
|
|
JOIN prod_mipih_noyau.DA_DOSADM ON no_sejour_administratif = DOS_IEP
|
|
|
JOIN prod_mipih_noyau.PA_PAT ON DA_DOSADM.PAT_IPP = PA_PAT.PAT_IPP
|
|
|
WHERE p_identites.rss_id = p_rss.oid AND
|
|
|
date_naissance = date(ETC_DDN) AND
|
|
|
(
|
|
|
nom IS DISTINCT FROM CASE WHEN ETC_NOM_MAR <> '' THEN ETC_NOM_MAR ELSE ETC_NOM END OR
|
|
|
nom_naissance IS DISTINCT FROM CASE WHEN ETC_NOM_MAR <> '' THEN ETC_NOM ELSE '' END OR
|
|
|
prenom IS DISTINCT FROM ETC_PRN
|
|
|
);
|
|
|
|
|
|
|
|
|
UPDATE [SCHEMA].p_identites SET
|
|
|
nom = CASE WHEN ETC_NOM_MAR <> '' THEN ETC_NOM_MAR ELSE ETC_NOM END,
|
|
|
nom_naissance = CASE WHEN ETC_NOM_MAR <> '' THEN ETC_NOM ELSE '' END,
|
|
|
prenom = ETC_PRN
|
|
|
FROM [SCHEMA].p_rss
|
|
|
JOIN prod_mipih_noyau.DA_DOSADM ON no_sejour_administratif = DOS_IEP
|
|
|
JOIN prod_mipih_noyau.PA_PAT ON DA_DOSADM.PAT_IPP = PA_PAT.PAT_IPP
|
|
|
WHERE p_identites.rss_id = p_rss.oid AND
|
|
|
date_part('year',date_naissance) = date_part('year',ETC_DDN) AND
|
|
|
nom LIKE 'RSS %' AND
|
|
|
(
|
|
|
nom IS DISTINCT FROM CASE WHEN ETC_NOM_MAR <> '' THEN ETC_NOM_MAR ELSE ETC_NOM END OR
|
|
|
nom_naissance IS DISTINCT FROM CASE WHEN ETC_NOM_MAR <> '' THEN ETC_NOM ELSE '' END OR
|
|
|
prenom IS DISTINCT FROM ETC_PRN
|
|
|
);
|
|
|
|
|
|
-- Médecin d'après les actes
|
|
|
UPDATE [SCHEMA].p_rss
|
|
|
SET medecin_rss_id = subview.medecin_rss_id
|
|
|
FROM
|
|
|
(
|
|
|
SELECT p_rss.oid, MAX(t_medecins.oid) AS medecin_rss_id
|
|
|
FROM [SCHEMA].p_rss
|
|
|
JOIN prod_mipih_noyau.DA_DOSADM ON no_sejour_administratif = DA_DOSADM.DOS_IEP
|
|
|
JOIN prod_mipih_noyau.PA_PAT ON DA_DOSADM.PAT_IPP = PA_PAT.PAT_IPP
|
|
|
JOIN prod_mipih_noyau.DA_ACT ON DA_DOSADM.DOS_IEP = DA_ACT.DOS_IEP
|
|
|
JOIN prod_mipih_noyau.CV_MED_UF ON DA_DOSADM.DOS_DERUFM = MED_UF_CD_UF AND
|
|
|
DA_ACT.ACT_CDMED = MED_UF_CD_MED
|
|
|
JOIN pmsi.t_medecins ON ACT_CDMED = t_medecins.code
|
|
|
WHERE act_iacnom IN ('TLETCLE', 'CCAM') AND
|
|
|
ACT_CDACTE NOT IN ('AMI', 'B') AND
|
|
|
ACT_CODACTI <> '4' AND
|
|
|
ACT_LC <> 'ADI' AND
|
|
|
ACT_CDACTE NOT IN ('DEQP003')
|
|
|
GROUP BY 1
|
|
|
HAVING count(DISTINCT ACT_CDMED) = 1
|
|
|
) subview
|
|
|
WHERE p_rss.oid = subview.oid AND p_rss.medecin_rss_id = 0;
|
|
|
|
|
|
|
|
|
UPDATE [SCHEMA].p_rss
|
|
|
SET medecin_rss_id = subview.medecin_rss_id
|
|
|
FROM
|
|
|
(
|
|
|
SELECT p_rss.oid, MAX(t_medecins.oid) AS medecin_rss_id
|
|
|
FROM [SCHEMA].p_rss
|
|
|
JOIN prod_mipih_noyau.DA_DOSADM ON no_sejour_administratif = DA_DOSADM.DOS_IEP
|
|
|
JOIN prod_mipih_noyau.PA_PAT ON DA_DOSADM.PAT_IPP = PA_PAT.PAT_IPP
|
|
|
JOIN prod_mipih_noyau.DA_ACT ON DA_DOSADM.DOS_IEP = DA_ACT.DOS_IEP
|
|
|
JOIN pmsi.t_medecins ON ACT_CDMED = t_medecins.code
|
|
|
WHERE act_iacnom IN ('TLETCLE', 'CCAM') AND
|
|
|
ACT_CDACTE NOT IN ('AMI', 'B') AND
|
|
|
ACT_CODACTI <> '4' AND
|
|
|
ACT_LC <> 'ADI' AND
|
|
|
ACT_CDACTE NOT IN ('DEQP003')
|
|
|
GROUP BY 1
|
|
|
HAVING count(DISTINCT ACT_CDMED) = 1
|
|
|
) subview
|
|
|
WHERE p_rss.oid = subview.oid AND p_rss.medecin_rss_id = 0;
|
|
|
|
|
|
|
|
|
|
|
|
]]></sqlcmd>
|
|
|
</NODE>
|
|
|
|
|
|
<NODE label="Unités médicales">
|
|
|
<sqlcmd><![CDATA[
|
|
|
|
|
|
UPDATE [SCHEMA].p_rss SET
|
|
|
unite_medicale_principale_id = t_unites_medicales.oid
|
|
|
FROM prod_mipih_noyau.DA_DOSADM
|
|
|
JOIN pmsi.t_unites_medicales ON t_unites_medicales.code = DOS_DERUFM
|
|
|
JOIN prod_mipih_noyau.PA_PAT ON DA_DOSADM.PAT_IPP = PA_PAT.PAT_IPP
|
|
|
WHERE no_sejour_administratif = DOS_IEP AND
|
|
|
date_naissance = date(ETC_DDN) AND
|
|
|
unite_medicale_principale_id = 0;
|
|
|
|
|
|
UPDATE [SCHEMA].p_rss SET
|
|
|
unite_medicale_principale_id = t_unites_medicales.oid
|
|
|
FROM prod_mipih_noyau.DA_DOSADM
|
|
|
JOIN pmsi.t_unites_medicales ON t_unites_medicales.code = DOS_DERUFM
|
|
|
JOIN prod_mipih_noyau.PA_PAT ON DA_DOSADM.PAT_IPP = PA_PAT.PAT_IPP
|
|
|
WHERE no_sejour_administratif = DOS_IEP AND
|
|
|
date_part('year',date_naissance) = date_part('year',ETC_DDN) AND
|
|
|
unite_medicale_principale_id = 0;
|
|
|
|
|
|
|
|
|
UPDATE [SCHEMA].p_rss_rum
|
|
|
SET unite_medicale_id = unite_medicale_principale_id
|
|
|
FROM [SCHEMA].p_rss
|
|
|
WHERE p_rss_rum.rss_id = p_rss.oid AND
|
|
|
unite_medicale_id = 0;
|
|
|
|
|
|
]]></sqlcmd>
|
|
|
</NODE>
|
|
|
|
|
|
<NODE label="Médecins actes">
|
|
|
<sqlcmd><![CDATA[
|
|
|
|
|
|
UPDATE [SCHEMA].p_rss_actes
|
|
|
SET medecin_id = subview.medecin_id
|
|
|
FROM (
|
|
|
SELECT p_rss_actes.no_rss, p_rss_actes.rss_id, p_rss_actes.date_acte, p_rss_actes.acte_id, p_rss_actes.activite_ccam, MAX(t_medecins.oid) AS medecin_id
|
|
|
FROM [SCHEMA].p_rss
|
|
|
JOIN prod_mipih_noyau.DA_DOSADM ON no_sejour_administratif = DA_DOSADM.DOS_IEP
|
|
|
JOIN prod_mipih_noyau.PA_PAT ON DA_DOSADM.PAT_IPP = PA_PAT.PAT_IPP
|
|
|
JOIN [SCHEMA].p_rss_actes ON p_rss_actes.rss_id = p_rss.oid
|
|
|
JOIN pmsi.t_actes ON acte_id = t_actes.oid
|
|
|
JOIN prod_mipih_noyau.DA_ACT ON DA_DOSADM.DOS_IEP = DA_ACT.DOS_IEP AND
|
|
|
date_acte = date(ACT_DTREAL) AND
|
|
|
t_actes.code = substring(ACT_CDACTE, 1, 7) AND
|
|
|
activite_ccam = ACT_CODACTI
|
|
|
JOIN pmsi.t_medecins ON ACT_CDMED = t_medecins.code
|
|
|
WHERE date_naissance = date(ETC_DDN) AND
|
|
|
p_rss_actes.medecin_id <> t_medecins.oid
|
|
|
GROUP BY 1,2,3,4,5
|
|
|
) subview
|
|
|
WHERE
|
|
|
p_rss_actes.rss_id = subview.rss_id AND
|
|
|
p_rss_actes.date_acte = subview.date_acte AND
|
|
|
p_rss_actes.acte_id = subview.acte_id AND
|
|
|
p_rss_actes.activite_ccam = subview.activite_ccam;
|
|
|
|
|
|
|
|
|
UPDATE [SCHEMA].p_rss_actes
|
|
|
SET medecin_id = subview.medecin_id
|
|
|
FROM (
|
|
|
SELECT p_rss_actes.no_rss, p_rss_actes.rss_id, p_rss_actes.date_acte, p_rss_actes.acte_id, p_rss_actes.activite_ccam, MAX(t_medecins.oid) AS medecin_id
|
|
|
FROM [SCHEMA].p_rss
|
|
|
JOIN prod_mipih_noyau.DA_DOSADM ON no_sejour_administratif = DA_DOSADM.DOS_IEP
|
|
|
JOIN prod_mipih_noyau.PA_PAT ON DA_DOSADM.PAT_IPP = PA_PAT.PAT_IPP
|
|
|
JOIN [SCHEMA].p_rss_actes ON p_rss_actes.rss_id = p_rss.oid
|
|
|
JOIN pmsi.t_actes ON acte_id = t_actes.oid
|
|
|
JOIN prod_mipih_noyau.DA_ACT ON DA_DOSADM.DOS_IEP = DA_ACT.DOS_IEP AND
|
|
|
date_acte = date(ACT_DTREAL) AND
|
|
|
t_actes.code = substring(ACT_CDACTE, 1, 7) AND
|
|
|
activite_ccam = ACT_CODACTI
|
|
|
JOIN pmsi.t_medecins ON ACT_CDMED = t_medecins.code
|
|
|
WHERE date_part('year',date_naissance) = date_part('year',ETC_DDN) AND
|
|
|
p_rss_actes.medecin_id = 0
|
|
|
GROUP BY 1,2,3,4,5
|
|
|
) subview
|
|
|
WHERE
|
|
|
p_rss_actes.rss_id = subview.rss_id AND
|
|
|
p_rss_actes.date_acte = subview.date_acte AND
|
|
|
p_rss_actes.acte_id = subview.acte_id AND
|
|
|
p_rss_actes.activite_ccam = subview.activite_ccam;
|
|
|
|
|
|
|
|
|
]]></sqlcmd>
|
|
|
</NODE>
|
|
|
|
|
|
</NODE>
|
|
|
|
|
|
<NODE name="PMSIENCOURS" label="RECUPERATION DES DOSSIERS PMSI EN-COURS CORA">
|
|
|
|
|
|
|
|
|
|
|
|
</NODE>
|
|
|
|
|
|
</ROOT>
|