<?xml version="1.0" encoding="ISO-8859-1"?>
|
|
<ROOT>
|
|
<NODE name="PMSICOMPLEMENTS" label="RECUPERATION DES DONNEES COMPLEMENTAIRES PMSI">
|
|
<NODE label="Parametres">
|
|
<sqlcmd><![CDATA[
|
|
|
|
-- Médecins Table ABZUR_LST_MA
|
|
INSERT INTO pmsi.t_medecins(code, nom, prenom, specialite_id, no_adeli, specialite_interne_id)
|
|
SELECT
|
|
MITARBEITER.MA_KURZ,
|
|
MAX(NATPERSON.NAME),
|
|
upper(MAX(NATPERSON.VORNAME)),
|
|
0,
|
|
'',
|
|
0
|
|
FROM prod_orbis.MITARBEITER
|
|
JOIN prod_orbis.NATPERSON ON MITARBEITER.PERSNR = NATPERSON.PERSNR
|
|
JOIN prod_orbis.ABZUR_LST_MA ON MITARBEITER.MAID = ABZUR_LST_MA.MAID
|
|
LEFT JOIN pmsi.t_medecins ON (MITARBEITER.MA_KURZ = t_medecins.code)
|
|
WHERE t_medecins.code IS NULL
|
|
GROUP BY 1;
|
|
|
|
-- Médecins Table ABZUR_LST
|
|
INSERT INTO pmsi.t_medecins(code, nom, prenom, specialite_id, no_adeli, specialite_interne_id)
|
|
SELECT
|
|
MITARBEITER.MA_KURZ,
|
|
MAX(NATPERSON.NAME),
|
|
upper(MAX(NATPERSON.VORNAME)),
|
|
0,
|
|
'',
|
|
0
|
|
FROM prod_orbis.MITARBEITER
|
|
JOIN prod_orbis.NATPERSON ON MITARBEITER.PERSNR = NATPERSON.PERSNR
|
|
JOIN prod_orbis.ABZUR_LST ON MITARBEITER.MAID = ABZUR_LST.MAID
|
|
LEFT JOIN pmsi.t_medecins ON (MITARBEITER.MA_KURZ = t_medecins.code)
|
|
WHERE t_medecins.code IS NULL
|
|
GROUP BY 1;
|
|
|
|
-- Médecins Table HRPRA
|
|
INSERT INTO pmsi.t_medecins(code, nom, prenom, specialite_id, no_adeli, specialite_interne_id)
|
|
SELECT
|
|
HRPRA.PRAACC as code
|
|
,HRPRA.PRANOM as nom
|
|
,HRPRA.PRAPREN as prenom
|
|
,COALESCE(t_specialites_medecin.oid, 0) as specialite_id
|
|
,HRPRA.RPPS as no_adeli
|
|
,0::bigint as specialite_interne_id
|
|
FROM
|
|
prod_orbis.HRDOS
|
|
JOIN prod_orbis.HRPRA ON HRPRA.PRAACC = HRDOS.XPRAACC
|
|
LEFT JOIN pmsi.t_medecins ON t_medecins.code = HRPRA.PRAACC
|
|
LEFT JOIN pmsi.t_specialites_medecin ON t_specialites_medecin.code = HRPRA.SPECACC
|
|
WHERE t_medecins.code IS NULL
|
|
GROUP BY HRPRA.PRAACC, HRPRA.PRANOM, HRPRA.PRAPREN, t_specialites_medecin.oid, HRPRA.RPPS;
|
|
|
|
|
|
-- Médecins Table CW_PRIMITIVUM
|
|
INSERT INTO pmsi.t_medecins(code, nom, prenom, specialite_id, no_adeli, specialite_interne_id)
|
|
SELECT
|
|
MITARBEITER.MA_KURZ
|
|
,MAX(NATPERSON.NAME)
|
|
,upper(MAX(NATPERSON.VORNAME))
|
|
,0
|
|
,''::text
|
|
,0
|
|
FROM
|
|
prod_orbis.MITARBEITER
|
|
JOIN prod_orbis.NATPERSON ON MITARBEITER.PERSNR = NATPERSON.PERSNR
|
|
JOIN prod_orbis.CW_PRIMITIVUM ON MITARBEITER.MAID = CW_PRIMITIVUM.MEDUSER
|
|
JOIN prod_orbis.CW_VERWEIS ON CW_PRIMITIVUM.PRIMITIVUMNUMMER = CW_VERWEIS.SOHNREFERENZ
|
|
AND CW_PRIMITIVUM.ERZEUGERKLASSE = CW_VERWEIS.VATERKLASSE
|
|
JOIN prod_orbis.CW_PRIMITIVUMINFO ON CW_PRIMITIVUMINFO.PRIMITIVUMNUMMER = CW_VERWEIS.SOHNREFERENZ
|
|
JOIN prod_orbis.FALL ON CW_VERWEIS.FALL = FALL.FALLID
|
|
JOIN pmsi.p_rss ON FALL.FALLNR = p_rss.no_sejour_administratif
|
|
LEFT JOIN pmsi.t_medecins ON t_medecins.code = MITARBEITER.MA_KURZ
|
|
WHERE
|
|
t_medecins.code IS NULL
|
|
AND CW_PRIMITIVUMINFO.STATUSSTRING ILIKE 'sign%' AND CW_PRIMITIVUMINFO.DOKNAMESTRING ILIKE 'courrier m%'
|
|
GROUP BY MITARBEITER.MA_KURZ ORDER BY 2;
|
|
|
|
|
|
-- Unités médicales d'après HRACTR
|
|
DROP TABLE IF EXISTS w_HRACTR;
|
|
CREATE TEMP TABLE w_HRACTR AS
|
|
SELECT
|
|
ORGAEBENE.OEBENEKURZ as um_code,
|
|
MAX(ORGAEBENE.OEBENENAME) as um_texte
|
|
FROM
|
|
prod_orbis.HRACTR
|
|
JOIN prod_orbis.ORGAEBENE ON ORGAEBENE.OEBENEKURZ = HRACTR.UF
|
|
GROUP BY 1;
|
|
|
|
INSERT INTO pmsi.t_unites_medicales (code, texte)
|
|
SELECT
|
|
um_code,
|
|
um_texte
|
|
FROM
|
|
w_HRACTR
|
|
LEFT JOIN pmsi.t_unites_medicales um ON um.code = w_HRACTR.um_code
|
|
WHERE
|
|
um.code IS NULL;
|
|
|
|
-- Unités médicales d'après table AMBU_BEHANDTAGE
|
|
INSERT INTO pmsi.t_unites_medicales (code, texte)
|
|
SELECT
|
|
ORGAEBENE.OEBENEKURZ,
|
|
MAX(ORGAEBENE.OEBENENAME)
|
|
FROM [SCHEMA].p_rss_rum
|
|
JOIN [SCHEMA].p_rss ON p_rss_rum.rss_id = p_rss.oid
|
|
JOIN prod_orbis.FALL ON p_rss.no_sejour_administratif = FALL.FALLNR
|
|
JOIN prod_orbis.AMBU_BEHANDTAGE ON AMBU_BEHANDTAGE.FALLID = FALL.FALLID
|
|
JOIN prod_orbis.ORGAEBENE ON ORGAEBENE.OEBENEID = AMBU_BEHANDTAGE.OEBENEID
|
|
LEFT JOIN pmsi.t_unites_medicales ON t_unites_medicales.code = ORGAEBENE.OEBENEKURZ
|
|
WHERE p_rss_rum.unite_medicale_id = 0 AND t_unites_medicales.oid IS NULL
|
|
GROUP BY 1
|
|
ORDER BY 1;
|
|
|
|
|
|
UPDATE pmsi.t_unites_medicales
|
|
SET texte = subview.OEBENENAME
|
|
FROM
|
|
(
|
|
SELECT ORGAEBENE.OEBENEKURZ,
|
|
(MAX(ARRAY[to_char(LDATE, 'YYYYMMDD'), OEBENENAME]))[2] AS OEBENENAME
|
|
FROM prod_orbis.ORGAEBENE
|
|
JOIN pmsi.t_unites_medicales ON ORGAEBENE.OEBENEKURZ = t_unites_medicales.code
|
|
GROUP BY ORGAEBENE.OEBENEKURZ
|
|
ORDER BY 1
|
|
) subview
|
|
WHERE t_unites_medicales.code = subview.OEBENEKURZ AND
|
|
t_unites_medicales.texte IS DISTINCT FROM subview.OEBENENAME;
|
|
|
|
]]></sqlcmd>
|
|
</NODE>
|
|
<NODE label="Identites">
|
|
<sqlcmd><![CDATA[
|
|
|
|
UPDATE [SCHEMA].p_identites SET
|
|
nom = NATPERSON.NAME,
|
|
prenom = NATPERSON.VORNAME,
|
|
nom_naissance = NATPERSON.GEBURTSNAME
|
|
FROM [SCHEMA].p_rss
|
|
JOIN prod_orbis.FALL ON FALL.FALLNR = p_rss.no_sejour_administratif
|
|
JOIN prod_orbis.NATPERSON ON FALL.PERSNR = NATPERSON.PERSNR
|
|
WHERE p_identites.rss_id = p_rss.oid AND
|
|
p_rss.date_naissance = date(NATPERSON.GEBDAT) AND
|
|
(
|
|
p_identites.nom IS DISTINCT FROM NATPERSON.NAME OR
|
|
p_identites.prenom IS DISTINCT FROM NATPERSON.VORNAME OR
|
|
p_identites.nom_naissance IS DISTINCT FROM NATPERSON.GEBURTSNAME
|
|
);
|
|
|
|
]]></sqlcmd>
|
|
</NODE>
|
|
<NODE label="Unites medicales">
|
|
<sqlcmd><![CDATA[
|
|
|
|
-- UM Principale des externes d'après table HRDOS
|
|
UPDATE [SCHEMA].p_rss SET
|
|
unite_medicale_principale_id = t_unites_medicales.oid
|
|
FROM
|
|
prod_orbis.HRDOS,
|
|
pmsi.t_unites_medicales
|
|
WHERE 1=1
|
|
AND p_rss.ghm_id = 0
|
|
AND p_rss.unite_medicale_principale_id = 0
|
|
AND p_rss.no_sejour_administratif = HRDOS.DOSNUM
|
|
AND p_rss.nb_rum = 1
|
|
AND p_rss.import_id = [IMPORT_ID]
|
|
AND HRDOS.UF = t_unites_medicales.code;
|
|
|
|
|
|
-- UM Principale des externes d'après table HRACTR si pas possible par HRDOS
|
|
-- On prend l'UM du premier acte de la liste dans HRACTR, on support qu'ils sont tous faits dans la même UM (à ameliorer éventuellement)
|
|
UPDATE [SCHEMA].p_rss SET
|
|
unite_medicale_principale_id = t_unites_medicales.oid
|
|
FROM
|
|
prod_orbis.HRACTR,
|
|
pmsi.t_unites_medicales
|
|
WHERE 1=1
|
|
AND p_rss.ghm_id = 0
|
|
AND p_rss.unite_medicale_principale_id = 0
|
|
AND p_rss.no_sejour_administratif = HRACTR.DOSNUM
|
|
AND p_rss.nb_rum = 1
|
|
AND p_rss.import_id = [IMPORT_ID]
|
|
AND HRACTR.ACTRNORD = 1
|
|
AND HRACTR.UF = t_unites_medicales.code;
|
|
|
|
|
|
-- Répercution sur la table des RUMS
|
|
UPDATE [SCHEMA].p_rss_rum SET
|
|
unite_medicale = t_unites_medicales.code,
|
|
unite_medicale_id = t_unites_medicales.oid
|
|
FROM
|
|
[SCHEMA].p_rss,
|
|
pmsi.t_unites_medicales
|
|
WHERE 1=1
|
|
AND p_rss.oid = p_rss_rum.rss_id
|
|
AND p_rss.ghm_id = 0
|
|
AND p_rss.import_id = [IMPORT_ID]
|
|
AND p_rss.unite_medicale_principale_id = t_unites_medicales.oid
|
|
AND p_rss_rum.unite_medicale_id = 0;
|
|
|
|
|
|
-- Répercution sur la table des actes
|
|
-- On ne passe pas pas la table HRACTR car les UF renseignées peuvent différer de celle renseignée dans HRDOS
|
|
-- Comme on part du principe que les externes sont monoRUMs, on applique celle de HRDOS
|
|
UPDATE [SCHEMA].p_rss_actes SET
|
|
unite_medicale = t_unites_medicales.code,
|
|
unite_medicale_id = t_unites_medicales.oid
|
|
FROM
|
|
[SCHEMA].p_rss,
|
|
pmsi.t_unites_medicales
|
|
WHERE 1=1
|
|
AND p_rss.oid = p_rss_actes.rss_id
|
|
AND p_rss.ghm_id = 0
|
|
AND p_rss.import_id = [IMPORT_ID]
|
|
AND p_rss.unite_medicale_principale_id = t_unites_medicales.oid
|
|
AND p_rss_actes.unite_medicale_id = 0;
|
|
|
|
|
|
-- Remontée d'infos dans p_rss au besoin
|
|
UPDATE [SCHEMA].p_rss SET
|
|
no_rum_principal = p_rss_rum.no_rum,
|
|
diagnostic_principal_id = p_rss_rum.diagnostic_principal_id,
|
|
diagnostic_relie_id = p_rss_rum.diagnostic_relie_id
|
|
FROM [SCHEMA].p_rss_rum
|
|
WHERE 1=1
|
|
AND p_rss.oid = p_rss_rum.rss_id
|
|
AND p_rss.nb_rum = 1
|
|
AND p_rss.import_id = [IMPORT_ID]
|
|
AND ( 1 <> 1
|
|
OR p_rss.no_rum_principal <> p_rss_rum.no_rum
|
|
OR p_rss.diagnostic_principal_id <> p_rss_rum.diagnostic_principal_id
|
|
OR p_rss.diagnostic_relie_id <> p_rss_rum.diagnostic_relie_id
|
|
);
|
|
|
|
]]></sqlcmd>
|
|
</NODE>
|
|
<NODE label="Medecins actes">
|
|
<sqlcmd><![CDATA[
|
|
|
|
-- Médecin exécutant depuis table HRACTR
|
|
UPDATE [SCHEMA].p_rss_actes SET
|
|
medecin_id = COALESCE(t_medecins.oid, 0)
|
|
FROM
|
|
[SCHEMA].p_rss
|
|
JOIN prod_orbis.HRACTR ON HRACTR.DOSNUM = p_rss.no_sejour_administratif
|
|
LEFT JOIN pmsi.t_medecins ON t_medecins.code = HRACTR.PRAACC,
|
|
pmsi.t_actes
|
|
WHERE 1=1
|
|
AND p_rss.oid = p_rss_actes.rss_id
|
|
AND t_actes.oid = p_rss_actes.acte_id
|
|
AND t_actes.code = HRACTR.ACTACC1
|
|
AND p_rss_actes.date_acte = HRACTR.ACTRD
|
|
AND p_rss.import_id = [IMPORT_ID]
|
|
AND p_rss_actes.activite_ccam = substr(HRACTR.ACTRDES, 8, 1)
|
|
AND p_rss_actes.medecin_id = 0;
|
|
|
|
|
|
-- Médecins exécutants d'après la table INTERVENTION
|
|
DROP TABLE IF EXISTS w_INTERVENTION;
|
|
CREATE TEMP TABLE w_INTERVENTION AS
|
|
SELECT
|
|
FALL.FALLNR,
|
|
p_rss.oid AS rss_id,
|
|
date(ABZUR_LSTADDITIONAL.DATACT) AS DATACT,
|
|
substr(ABZUR_LSTADDITIONAL.CODELAB,1,7) AS code_acte,
|
|
substr(ABZUR_LSTADDITIONAL.CODELAB,8,1) AS activite_ccam,
|
|
MAX(ABZUR_LST.MAID) AS MAID,
|
|
MAX(MITARBEITER.MA_KURZ) AS MA_KURZ
|
|
FROM prod_orbis.INTERVENTION
|
|
JOIN prod_orbis.FALL on INTERVENTION.FALLID = FALL.FALLID
|
|
JOIN prod_orbis.NATPERSON ON FALL.PERSNR = NATPERSON.PERSNR
|
|
JOIN [SCHEMA].p_rss ON FALL.FALLNR = p_rss.no_sejour_administratif
|
|
JOIN prod_orbis.ABZUR_LSTADDITIONAL ON ABZUR_LSTADDITIONAL.INTERVENTIONID = INTERVENTION.INTERVENTIONID
|
|
JOIN prod_orbis.ABZUR_LST ON ABZUR_LST.LEISTUNG_ID = ABZUR_LSTADDITIONAL.LEISTUNGID
|
|
JOIN prod_orbis.MITARBEITER ON MITARBEITER.MAID = ABZUR_LST.MAID
|
|
WHERE
|
|
p_rss.import_id = [IMPORT_ID]
|
|
GROUP BY 1,2,3,4,5
|
|
ORDER BY 1,2,3,4,5;
|
|
|
|
|
|
UPDATE [SCHEMA].p_rss_actes
|
|
SET medecin_id = t_medecins.oid
|
|
FROM pmsi.t_actes,
|
|
w_INTERVENTION
|
|
JOIN pmsi.t_medecins ON w_INTERVENTION.MA_KURZ = t_medecins.code
|
|
WHERE p_rss_actes.rss_id = w_INTERVENTION.rss_id AND
|
|
p_rss_actes.date_acte = w_INTERVENTION.DATACT AND
|
|
p_rss_actes.activite_ccam = w_INTERVENTION.activite_ccam AND
|
|
t_actes.code = w_INTERVENTION.code_acte AND
|
|
p_rss_actes.acte_id = t_actes.oid AND
|
|
p_rss_actes.medecin_id IS DISTINCT FROM t_medecins.oid;
|
|
|
|
|
|
-- Médecins actes d'après la table DATACTESCCAM
|
|
DROP TABLE IF EXISTS w_med_actes;
|
|
CREATE TEMP TABLE w_med_actes AS
|
|
SELECT
|
|
p_rss.no_sejour_administratif
|
|
,p_rss.oid as rss_id
|
|
,p_rss_actes.no_rum
|
|
,p_rss_actes.date_acte
|
|
,t_actes.oid as acte_id
|
|
,p_rss_actes.activite_ccam
|
|
,t_medecins.oid as medecin_id
|
|
FROM
|
|
prod_orbis.DATENTREE
|
|
JOIN prod_orbis.DATPASSAGE ON DATPASSAGE.PASIDENT = DATENTREE.ENTID
|
|
JOIN prod_orbis.DATRESUMEMCO ON DATRESUMEMCO.RSSENTID = DATPASSAGE.PASIDENT
|
|
JOIN prod_orbis.DATACTESCCAM ON DATACTESCCAM.ACTIDPASSCCAM = DATRESUMEMCO.RSSIDCLASSANT
|
|
JOIN [SCHEMA].p_rss ON p_rss.no_sejour_administratif = DATENTREE.ENTNUM
|
|
JOIN [SCHEMA].p_rss_actes ON p_rss_actes.rss_id = p_rss.oid
|
|
JOIN pmsi.t_actes ON t_actes.oid = p_rss_actes.acte_id
|
|
JOIN pmsi.t_medecins ON t_medecins.code = DATACTESCCAM.ACTEXECCCAM
|
|
WHERE 1=1
|
|
AND p_rss.import_id = [IMPORT_ID]
|
|
AND t_actes.code = DATACTESCCAM.ACTCODECCAM
|
|
AND p_rss_actes.activite_ccam = DATACTESCCAM.ACTACTIVITECCAM
|
|
AND p_rss_actes.date_acte = date(DATACTESCCAM.ACTDATECCAM)
|
|
AND p_rss_actes.no_rum = DATPASSAGE.PASINDEX
|
|
AND p_rss_actes.medecin_id = 0;
|
|
|
|
|
|
UPDATE [SCHEMA].p_rss_actes SET
|
|
medecin_id = w_med_actes.medecin_id
|
|
FROM
|
|
w_med_actes
|
|
WHERE 1=1
|
|
AND p_rss_actes.rss_id = w_med_actes.rss_id
|
|
AND p_rss_actes.date_acte = w_med_actes.date_acte
|
|
AND p_rss_actes.activite_ccam = w_med_actes.activite_ccam
|
|
AND p_rss_actes.no_rum = w_med_actes.no_rum
|
|
AND p_rss_actes.acte_id = w_med_actes.acte_id
|
|
AND p_rss_actes.medecin_id = 0;
|
|
|
|
]]></sqlcmd>
|
|
</NODE>
|
|
<NODE label="Medecins RSS">
|
|
<sqlcmd><![CDATA[
|
|
|
|
-- Médecins RSS selon la table HRDOS
|
|
UPDATE [SCHEMA].p_rss SET
|
|
medecin_rss_id = t_medecins.oid
|
|
FROM
|
|
prod_orbis.HRDOS,
|
|
pmsi.t_medecins
|
|
WHERE 1=1
|
|
AND p_rss.no_sejour_administratif = HRDOS.DOSNUM
|
|
AND p_rss.import_id = [IMPORT_ID]
|
|
AND p_rss.medecin_rss_id = 0
|
|
AND HRDOS.XPRAACC = t_medecins.code
|
|
AND HRDOS.XPRAACC IS DISTINCT FROM '';
|
|
|
|
|
|
-- Médecin RSS selon actes
|
|
DROP TABLE IF EXISTS w_rss_actes;
|
|
CREATE TEMP TABLE w_rss_actes AS
|
|
SELECT
|
|
p_rss_actes.rss_id,
|
|
(COALESCE(
|
|
MAX(
|
|
CASE WHEN activite_ccam <> '4' AND
|
|
t_actes_c.ccam_regroupement_code_1 <> 'ADI' AND
|
|
t_actes_c.ccam_regroupement_code_1 <> 'ADA' AND
|
|
t_actes_c.ccam_regroupement_code_1 <> 'ADE' AND
|
|
t_actes_c.ccam_regroupement_code_1 <> 'ATM'
|
|
THEN Array[t_actes_c.icr_1,medecin_id] ELSE NULL END),
|
|
MAX(
|
|
CASE WHEN activite_ccam <> '4' AND
|
|
t_actes_c.ccam_regroupement_code_1 <> 'ADI' AND
|
|
t_actes_c.ccam_regroupement_code_1 <> 'ADA' AND
|
|
t_actes_c.ccam_regroupement_code_1 <> 'ATM'
|
|
THEN Array[t_actes_c.icr_1,medecin_id] ELSE NULL END),
|
|
MAX(
|
|
CASE WHEN activite_ccam <> '4' AND
|
|
t_actes_c.ccam_regroupement_code_1 <> 'ADI' AND
|
|
t_actes_c.ccam_regroupement_code_1 <> 'ADA'
|
|
THEN Array[t_actes_c.icr_1,medecin_id] ELSE NULL END),
|
|
MAX(
|
|
CASE WHEN activite_ccam <> '4' AND
|
|
t_actes_c.ccam_regroupement_code_1 <> 'ADA'
|
|
THEN Array[t_actes_c.icr_1,medecin_id] ELSE NULL END),
|
|
Array[0,0]
|
|
))[2]::bigint AS medecin_id
|
|
FROM
|
|
[SCHEMA].p_rss_actes
|
|
JOIN [SCHEMA].p_rss ON p_rss.oid = p_rss_actes.rss_id
|
|
JOIN pmsi.t_actes_c ON p_rss_actes.acte_id = t_actes_c.oid
|
|
WHERE
|
|
p_rss.import_id = [IMPORT_ID]
|
|
GROUP BY 1;
|
|
|
|
|
|
UPDATE [SCHEMA].p_rss
|
|
SET medecin_rss_id = w_rss_actes.medecin_id
|
|
FROM w_rss_actes
|
|
WHERE w_rss_actes.rss_id = p_rss.oid AND
|
|
p_rss.medecin_rss_id <> w_rss_actes.medecin_id AND
|
|
w_rss_actes.medecin_id <> 0;
|
|
|
|
-- Pour les séjours sans actes et sans médecin responsable renseigné
|
|
-- on va regarder dans la liste des documents du dossier médical
|
|
-- Le médecin qui a signé le courrier médical peut être le médecin responsable du séjour
|
|
|
|
UPDATE [SCHEMA].p_rss
|
|
SET
|
|
medecin_rss_id = t_medecins.oid
|
|
FROM
|
|
prod_orbis.FALL
|
|
JOIN prod_orbis.CW_VERWEIS ON CW_VERWEIS.FALL = FALL.FALLID
|
|
JOIN prod_orbis.CW_PRIMITIVUM ON CW_PRIMITIVUM.PRIMITIVUMNUMMER = CW_VERWEIS.SOHNREFERENZ
|
|
AND CW_PRIMITIVUM.ERZEUGERKLASSE = CW_VERWEIS.VATERKLASSE
|
|
JOIN prod_orbis.CW_PRIMITIVUMINFO ON CW_PRIMITIVUMINFO.PRIMITIVUMNUMMER = CW_VERWEIS.SOHNREFERENZ
|
|
JOIN prod_orbis.MITARBEITER on MITARBEITER.MAID = CW_PRIMITIVUM.MEDUSER
|
|
JOIN pmsi.t_medecins ON t_medecins.code = MITARBEITER.MA_KURZ
|
|
WHERE 1=1
|
|
AND FALL.FALLNR = p_rss.no_sejour_administratif
|
|
AND p_rss.import_id = [IMPORT_ID]
|
|
AND p_rss.medecin_rss_id = 0
|
|
AND CW_PRIMITIVUMINFO.STATUSSTRING ILIKE 'sign%' AND CW_PRIMITIVUMINFO.DOKNAMESTRING ILIKE 'courrier m%';
|
|
|
|
|
|
]]></sqlcmd>
|
|
</NODE>
|
|
</NODE>
|
|
<NODE name="PMSIENCOURS" label="RECUPERATION DES DOSSIERS PMSI EN-COURS ORBIS">
|
|
<NODE label="Parametres">
|
|
<sqlcmd><![CDATA[
|
|
|
|
-- Médecins Table ABZUR_LST_MA
|
|
INSERT INTO pmsi.t_medecins(code, nom, prenom, specialite_id, no_adeli, specialite_interne_id)
|
|
SELECT
|
|
MITARBEITER.MA_KURZ,
|
|
MAX(NATPERSON.NAME),
|
|
upper(MAX(NATPERSON.VORNAME)),
|
|
0,
|
|
'',
|
|
0
|
|
FROM prod_orbis.MITARBEITER
|
|
JOIN prod_orbis.NATPERSON ON MITARBEITER.PERSNR = NATPERSON.PERSNR
|
|
JOIN prod_orbis.ABZUR_LST_MA ON MITARBEITER.MAID = ABZUR_LST_MA.MAID
|
|
LEFT JOIN pmsi.t_medecins ON (MITARBEITER.MA_KURZ = t_medecins.code)
|
|
WHERE t_medecins.code IS NULL
|
|
GROUP BY 1;
|
|
|
|
-- Médecins Table ABZUR_LST
|
|
INSERT INTO pmsi.t_medecins(code, nom, prenom, specialite_id, no_adeli, specialite_interne_id)
|
|
SELECT
|
|
MITARBEITER.MA_KURZ,
|
|
MAX(NATPERSON.NAME),
|
|
upper(MAX(NATPERSON.VORNAME)),
|
|
0,
|
|
'',
|
|
0
|
|
FROM prod_orbis.MITARBEITER
|
|
JOIN prod_orbis.NATPERSON ON MITARBEITER.PERSNR = NATPERSON.PERSNR
|
|
JOIN prod_orbis.ABZUR_LST ON MITARBEITER.MAID = ABZUR_LST.MAID
|
|
LEFT JOIN pmsi.t_medecins ON (MITARBEITER.MA_KURZ = t_medecins.code)
|
|
WHERE t_medecins.code IS NULL
|
|
GROUP BY 1;
|
|
|
|
|
|
|
|
|
|
-- Unités médicales
|
|
INSERT INTO pmsi.t_unites_medicales (code, texte)
|
|
SELECT
|
|
ORGAEBENE.OEBENEKURZ,
|
|
MAX(ORGAEBENE.OEBENENAME)
|
|
FROM pmsi.p_rss_rum
|
|
JOIN pmsi.p_rss ON rss_id = p_rss.oid
|
|
JOIN prod_orbis.FALL ON p_rss.no_sejour_administratif = FALL.FALLNR
|
|
JOIN prod_orbis.AMBU_BEHANDTAGE ON AMBU_BEHANDTAGE.FALLID = FALL.FALLID
|
|
JOIN prod_orbis.ORGAEBENE ON ORGAEBENE.OEBENEID = AMBU_BEHANDTAGE.OEBENEID
|
|
LEFT JOIN pmsi.t_unites_medicales ON t_unites_medicales.code = ORGAEBENE.OEBENEKURZ
|
|
WHERE p_rss_rum.unite_medicale_id = 0 AND t_unites_medicales.oid IS NULL
|
|
GROUP BY 1
|
|
ORDER BY 1;
|
|
|
|
|
|
UPDATE pmsi.t_unites_medicales
|
|
SET texte = subview.OEBENENAME
|
|
FROM
|
|
(
|
|
SELECT ORGAEBENE.OEBENEKURZ,
|
|
COALESCE(
|
|
MAX(CASE WHEN ORGAEBENE.ORGANAMEID = 350 THEN ORGAEBENE.OEBENENAME ELSE NULL END),
|
|
MAX(CASE WHEN ORGAEBENE.ORGANAMEID <> 350 THEN ORGAEBENE.OEBENENAME ELSE NULL END)
|
|
) AS OEBENENAME
|
|
FROM prod_orbis.ORGAEBENE
|
|
JOIN pmsi.t_unites_medicales ON ORGAEBENE.OEBENEKURZ = t_unites_medicales.code
|
|
GROUP BY ORGAEBENE.OEBENEKURZ
|
|
ORDER BY 1
|
|
) subview
|
|
WHERE t_unites_medicales.code = subview.OEBENEKURZ AND
|
|
t_unites_medicales.texte IS DISTINCT FROM subview.OEBENENAME;
|
|
|
|
]]></sqlcmd>
|
|
</NODE>
|
|
<NODE label="RSS">
|
|
<sqlcmd><![CDATA[
|
|
|
|
|
|
DROP TABLE IF EXISTS w_finess;
|
|
CREATE TEMP TABLE w_finess AS
|
|
SELECT MAX(code) AS code FROM base.t_finess WHERE secondaire <> 1;
|
|
|
|
|
|
DROP TABLE IF EXISTS w_FALL;
|
|
CREATE TEMP TABLE w_FALL AS
|
|
SELECT
|
|
w_finess.code as finess
|
|
,nextval('pmsi.s_rss'::regclass) as rss_id
|
|
,FALL.FALLID
|
|
,FALL.FALLNR
|
|
,FALL.AUFNDAT
|
|
,FALL.ENTLDAT
|
|
,FALL.PERSNR
|
|
,NATPERSON.NAME AS NAME
|
|
,NATPERSON.GEBURTSNAME AS GEBURTSNAME
|
|
,NATPERSON.VORNAME AS VORNAME
|
|
FROM
|
|
w_finess,
|
|
prod_orbis.FALL
|
|
JOIN prod_orbis.NATPERSON ON FALL.PERSNR = NATPERSON.PERSNR
|
|
LEFT JOIN pmsi.p_rss ON FALL.FALLNR = p_rss.no_sejour_administratif
|
|
WHERE 1=1
|
|
AND p_rss.oid IS NULL
|
|
AND FALL.ENTLDAT BETWEEN '[ANNEE]0101' AND now();
|
|
|
|
|
|
DROP TABLE IF EXISTS w_rss;
|
|
CREATE TEMP TABLE w_rss AS
|
|
SELECT
|
|
w_FALL.finess
|
|
,w_FALL.FALLID
|
|
,0 - w_FALL.FALLID AS no_rss
|
|
,w_FALL.FALLNR
|
|
,w_FALL.rss_id
|
|
,'19811101'::date AS BIRTHDAY
|
|
,''::text AS SEX
|
|
,w_FALL.AUFNDAT
|
|
,w_FALL.ENTLDAT
|
|
,''::text AS ADMISSIONTYPE
|
|
,''::text AS ORIGIN
|
|
,''::text AS DISCHARGETYPE
|
|
,''::text AS DESTINATION
|
|
,''::text AS ZIPCODE
|
|
,0::integer AS BIRTHWEIGHT
|
|
,0::integer AS IGS2
|
|
,0::integer as NB_RSA
|
|
,0::integer AS NB_RUM
|
|
,0::integer as NB_SEANCES
|
|
,0::integer as GESTANR
|
|
,w_FALL.NAME
|
|
,w_FALL.GEBURTSNAME
|
|
,w_FALL.VORNAME
|
|
,''::text AS DRGGHM
|
|
,0 AS IS_GROUPED
|
|
,'20991231'::date AS VALIDATION_LASTDATE
|
|
,0::integer AS DRGGHS
|
|
,DATE(w_FALL.ENTLDAT) - DATE(w_FALL.AUFNDAT) AS DURSEJ
|
|
,0 as AGE
|
|
,'0'::text as IS_FACTURED
|
|
FROM
|
|
w_FALL;
|
|
|
|
|
|
DROP TABLE IF EXISTS w_DRGMCO;
|
|
CREATE TEMP TABLE w_DRGMCO AS
|
|
SELECT
|
|
w_FALL.FALLID
|
|
,MAX(date(FALL_DRGMCO.BIRTHDAY)) as BIRTHDAY
|
|
,MAX(COALESCE(FALL_DRGMCO.SEX,'1')) as SEX
|
|
,MAX(FALL_DRGMCO.ZIPCODE) as ZIPCODE
|
|
,MAX(FALL_DRGMCO.BIRTHWEIGHT) as BIRTHWEIGHT
|
|
,MAX(base.cti_to_number(FALL_DRGMCO.IGS2)) as IGS2
|
|
,MAX(GREATEST(1,FALL_DRGMCO.STAYNR)) as STAYNR
|
|
,COUNT(FALL_DRGMCO.FALL_DRGMCOID) as FALL_DRGMCOID
|
|
,MAX(FALL_DRGMCO.STAYNR) as NB_SEANCES
|
|
,MAX(FALL_DRGMCO.GESTANR) as GESTANR
|
|
,MAX(FALL_DRGRESULT.DRGCMD || FALL_DRGRESULT.DRGNUMBER) as DRGGHM
|
|
,max(FALL_DRGMCO.IS_GROUPED) as IS_GROUPED
|
|
,max(date(FALL_DRGMCO.VALIDATION_LASTDATE)) as VALIDATION_LASTDATE
|
|
,base.cti_to_number(MAX(EXTERNALSERVICE.TW_LSTNR)) as DRGGHS
|
|
,MIN(CATALOGTEXT.SHORTTEXT) as IS_FACTURED
|
|
FROM
|
|
w_FALL
|
|
JOIN prod_orbis.FALL_DRGMCO ON FALL_DRGMCO.FALLID = w_FALL.FALLID
|
|
JOIN prod_orbis.FALL_DRGRESULT ON FALL_DRGMCO.FALL_DRGMCOID = FALL_DRGRESULT.FALL_DRGMCOID
|
|
LEFT JOIN prod_orbis.EXTERNALSERVICE ON EXTERNALSERVICE.EXTERNALSERVICEID = FALL_DRGRESULT.GHSID
|
|
LEFT JOIN prod_orbis.CATALOGTEXT ON CATALOGTEXT.DBUID = FALL_DRGMCO.RUM_BILL_STATUS
|
|
WHERE 1=1
|
|
AND FALL_DRGRESULT.GRPCASEFLAG = 2
|
|
AND FALL_DRGMCO.VISIBILITY = 0
|
|
GROUP BY w_FALL.FALLID;
|
|
|
|
DELETE FROM w_rss
|
|
WHERE
|
|
FALLID != ALL(ARRAY(SELECT FALLID FROM w_DRGMCO)::bigint[]);
|
|
|
|
|
|
UPDATE w_rss SET
|
|
BIRTHDAY = w_DRGMCO.BIRTHDAY
|
|
,SEX = w_DRGMCO.SEX
|
|
,ZIPCODE = w_DRGMCO.ZIPCODE
|
|
,BIRTHWEIGHT = w_DRGMCO.BIRTHWEIGHT
|
|
,IGS2 = w_DRGMCO.IGS2
|
|
,NB_RSA = w_DRGMCO.STAYNR
|
|
,NB_RUM = w_DRGMCO.FALL_DRGMCOID
|
|
,NB_SEANCES = w_DRGMCO.STAYNR
|
|
,GESTANR = w_DRGMCO.GESTANR
|
|
,DRGGHM = w_DRGMCO.DRGGHM
|
|
,IS_GROUPED = w_DRGMCO.IS_GROUPED
|
|
,VALIDATION_LASTDATE = w_DRGMCO.VALIDATION_LASTDATE
|
|
,DRGGHS = w_DRGMCO.DRGGHS
|
|
,IS_FACTURED = w_DRGMCO.IS_FACTURED
|
|
FROM
|
|
w_DRGMCO
|
|
WHERE w_rss.FALLID = w_DRGMCO.FALLID;
|
|
|
|
|
|
-- Tout ce qui est codé en erreur obtient le GHM CTI 99Z99Z
|
|
UPDATE w_rss
|
|
SET DRGGHM = '99Z99Z'
|
|
WHERE 1!=1
|
|
OR DRGGHM LIKE '90%'
|
|
OR length(DRGGHM) <> 6
|
|
OR DRGGHM IS NULL;
|
|
|
|
|
|
INSERT INTO pmsi.p_rss (
|
|
finess
|
|
,oid
|
|
,no_rss
|
|
,no_patient
|
|
,version_groupage
|
|
,date_naissance
|
|
,sexe
|
|
,date_entree
|
|
,date_sortie
|
|
,mode_entree
|
|
,provenance
|
|
,mode_sortie
|
|
,destination
|
|
,code_postal
|
|
,poids_bebe
|
|
,igs2
|
|
,cma
|
|
,groupe_ghm
|
|
,duree_sejour
|
|
,nb_rsa
|
|
,age
|
|
,supprime
|
|
,date_import
|
|
,nb_rum
|
|
,secteur
|
|
,no_sejour_administratif
|
|
,nb_seances
|
|
,ghm_fg9
|
|
,ghm_id
|
|
,medecin_rss_id
|
|
,ghs_id
|
|
,mois_sortie
|
|
,diagnostic_principal_id
|
|
,diagnostic_relie_id
|
|
,ghm_production_id
|
|
,no_rum_principal
|
|
,unite_medicale_principale_id
|
|
,import_id
|
|
,etat
|
|
,acte_principal_id
|
|
,code_postal_id
|
|
,patient_id
|
|
,prestation_principale_id
|
|
,severite_fg11_simulation_code
|
|
,en_cours
|
|
,en_cours_etat
|
|
,base_remboursement
|
|
,sejour_facture
|
|
,honoraires_factures
|
|
,t2a_facture
|
|
,dmi_facture
|
|
,phc_facture
|
|
,ca_ghs_theorique
|
|
,nb_ghs
|
|
,ca_ghs
|
|
,nb_exb
|
|
,ca_exb
|
|
,nb_exh
|
|
,ca_exh
|
|
,nb_si
|
|
,ca_si
|
|
,nb_sur
|
|
,ca_sur
|
|
,nb_rea
|
|
,ca_rea
|
|
,nb_neonat
|
|
,ca_neonat
|
|
,traitement_epmsi
|
|
,code_retour_groupage
|
|
,comite_medical_id
|
|
,rehosp_meme_ghm
|
|
,from_oid
|
|
)
|
|
SELECT
|
|
w_rss.finess AS finess
|
|
,w_rss.rss_id AS oid
|
|
,w_rss.no_rss
|
|
,0 AS no_patient
|
|
,'11' AS version_groupage
|
|
,w_rss.BIRTHDAY AS date_naissance
|
|
,w_rss.SEX
|
|
,w_rss.AUFNDAT AS date_entree
|
|
,w_rss.ENTLDAT AS date_sortie
|
|
,w_rss.ADMISSIONTYPE AS mode_entree
|
|
,w_rss.ORIGIN AS provenance
|
|
,w_rss.DISCHARGETYPE AS mode_sortie
|
|
,w_rss.DESTINATION AS destination
|
|
,w_rss.ZIPCODE AS code_postal
|
|
,w_rss.BIRTHWEIGHT AS poids_bebe
|
|
,w_rss.IGS2 AS igs2
|
|
,'' AS cma
|
|
,substr(w_rss.DRGGHM , 3 , 1) AS groupe_ghm
|
|
,w_rss.DURSEJ AS duree_sejour
|
|
,w_rss.NB_RSA AS nb_rsa
|
|
,w_rss.AGE AS age
|
|
,'' AS supprime
|
|
,now() AS date_import
|
|
,w_rss.NB_RUM AS nb_rum
|
|
,'' AS secteur
|
|
,w_rss.FALLNR AS no_sejour_administratif
|
|
,w_rss.NB_SEANCES AS nb_seances
|
|
,'' AS ghm_fg9
|
|
,COALESCE(t_ghm.oid, 0) AS ghm_id
|
|
,0 AS medecin_rss_id
|
|
,COALESCE(t_ghs.oid, 0) AS ghs_id
|
|
,(extract(year from w_rss.ENTLDAT) * 100 + extract(month from w_rss.ENTLDAT))::integer AS mois_sortie
|
|
,0 AS diagnostic_principal_id
|
|
,0 AS diagnostic_relie_id
|
|
,COALESCE(t_ghm.oid, 0) AS ghm_production_id
|
|
,1 AS no_rum_principal
|
|
,0 AS unite_medicale_principale_id
|
|
,-1 AS import_id
|
|
,'' AS etat
|
|
,0 AS acte_principal_id
|
|
,0 AS code_postal_id
|
|
,0 AS patient_id
|
|
,0 AS prestation_principale_id
|
|
,'' AS severite_fg11_simulation_code
|
|
,'1' AS en_cours
|
|
,CASE WHEN w_rss.IS_GROUPED = 1 THEN 'G' ELSE 'S' END AS en_cours_etat
|
|
,0 AS base_remboursement
|
|
,0 AS sejour_facture
|
|
,0 AS honoraires_factures
|
|
,0 AS t2a_facture
|
|
,0 AS dmi_facture
|
|
,0 AS phc_facture
|
|
,0 AS ca_ghs_theorique
|
|
,0 AS nb_ghs
|
|
,0 AS ca_ghs
|
|
,0 AS nb_exb
|
|
,0 AS ca_exb
|
|
,0 AS nb_exh
|
|
,0 AS ca_exh
|
|
,0 AS nb_si
|
|
,0 AS ca_si
|
|
,0 AS nb_sur
|
|
,0 AS ca_sur
|
|
,0 AS nb_rea
|
|
,0 AS ca_rea
|
|
,0 AS nb_neonat
|
|
,0 AS ca_neonat
|
|
,'00' AS traitement_epmsi
|
|
,'' AS code_retour_groupage
|
|
,0 AS comite_medical_id
|
|
,'0' AS rehosp_meme_ghm
|
|
,0 AS from_oid
|
|
FROM w_rss
|
|
LEFT JOIN base.t_codes_postaux ON t_codes_postaux.code = w_rss.ZIPCODE
|
|
LEFT JOIN pmsi.t_ghm ON t_ghm.code = w_rss.DRGGHM
|
|
LEFT JOIN pmsi.t_ghs ON t_ghs.code = w_rss.DRGGHS;
|
|
|
|
]]></sqlcmd>
|
|
</NODE>
|
|
<NODE label="Identites">
|
|
<sqlcmd><![CDATA[
|
|
|
|
INSERT INTO pmsi.p_identites(
|
|
finess,
|
|
rss_id,
|
|
no_rss,
|
|
nom,
|
|
prenom,
|
|
nom_naissance)
|
|
SELECT
|
|
w_rss.finess
|
|
,w_rss.rss_id
|
|
,w_rss.no_rss
|
|
,w_rss.NAME
|
|
,w_rss.VORNAME
|
|
,w_rss.GEBURTSNAME
|
|
FROM
|
|
w_rss;
|
|
|
|
]]></sqlcmd>
|
|
</NODE>
|
|
<NODE label="Rum">
|
|
<sqlcmd><![CDATA[
|
|
|
|
-- Determination du numero de RUM
|
|
DROP TABLE IF EXISTS w_rum;
|
|
CREATE TEMP TABLE w_rum AS
|
|
SELECT
|
|
w_rss.rss_id
|
|
,w_rss.no_rss
|
|
,FALL_DRGMCO.FALL_DRGMCOID
|
|
,date(FALL_DRGMCO.STAYBEGIN) as STAYBEGIN
|
|
,date(FALL_DRGMCO.STAYEND) as STAYEND
|
|
,FALL_DRGMCO.ADMISSIONTYPE
|
|
,FALL_DRGMCO.ORIGIN
|
|
,FALL_DRGMCO.DISCHARGETYPE
|
|
,FALL_DRGMCO.DESTINATION
|
|
,FALL_DRGMCO.STAYNR
|
|
,FALL_DRGMCO.IS_MAINRUM
|
|
,FALL_DRGMCO.UMNR
|
|
,FALL_DRGMCO.AUTHORISATIONUM
|
|
,FALL_DRGMCO.AUTHORISATIONBED
|
|
,FALL_DRGMCO.IGS2
|
|
,0::bigint as diagnostic_principal_id
|
|
,0::bigint as diagnostic_relie_id
|
|
,0 as WRUM_NUMERO
|
|
,0 AS tmp_rum_num
|
|
,0 AS tmp_min_rum_num
|
|
,0 AS tmp_max_rum_num
|
|
FROM
|
|
w_rss
|
|
JOIN prod_orbis.FALL_DRGMCO ON FALL_DRGMCO.FALLID = w_rss.fallid
|
|
ORDER BY w_rss.rss_id, FALL_DRGMCO.STAYBEGIN;
|
|
|
|
DROP SEQUENCE IF EXISTS w_seq;
|
|
CREATE TEMP SEQUENCE w_seq;
|
|
|
|
UPDATE w_rum
|
|
SET tmp_rum_num = nextval('w_seq');
|
|
|
|
-- Determination du RUM min et du RUM max
|
|
UPDATE w_rum
|
|
SET
|
|
tmp_min_rum_num = subq.tmp_min_rum_num,
|
|
tmp_max_rum_num = subq.tmp_max_rum_num
|
|
FROM (
|
|
SELECT
|
|
w_rum.rss_id
|
|
,min(w_rum.tmp_rum_num) AS tmp_min_rum_num
|
|
,max(w_rum.tmp_rum_num) AS tmp_max_rum_num
|
|
FROM w_rum
|
|
GROUP BY w_rum.rss_id
|
|
) AS subq
|
|
WHERE w_rum.rss_id = subq.rss_id;
|
|
|
|
-- Affectation du numero de RUM
|
|
UPDATE w_rum
|
|
SET WRUM_NUMERO = tmp_rum_num - tmp_min_rum_num + 1;
|
|
|
|
-- Mise a jour de la date de sortie du dernier RUM avec la date de sortie du sejour
|
|
UPDATE w_rum SET
|
|
STAYEND = w_rss.entldat
|
|
FROM
|
|
w_rss
|
|
WHERE 1=1
|
|
AND w_rum.tmp_rum_num = w_rum.tmp_max_rum_num
|
|
AND w_rum.stayend is null
|
|
AND w_rss.no_rss = w_rum.no_rss;
|
|
|
|
|
|
|
|
-- Constat au moment du developpement : le disgnostic principal est repere dans prod_orbis.CATALOGDEF par le champ sortorder = '01
|
|
-- diagnostic relie : '02'
|
|
-- diagnostic associe : '06'
|
|
-- diagnostic documentaire : '07'
|
|
|
|
-- DP
|
|
UPDATE w_rum SET
|
|
diagnostic_principal_id = t_diagnostics.oid
|
|
FROM
|
|
prod_orbis.DRG_ICD
|
|
JOIN prod_orbis.CATALOGDEF ON CATALOGDEF.DBUID = DRG_ICD.DIAGNOSISTYPE
|
|
JOIN prod_orbis.DIAGNOSEN ON DIAGNOSEN.DIAGNOSEID = DRG_ICD.DIAGNOSEID
|
|
JOIN pmsi.t_diagnostics ON t_diagnostics.code = DIAGNOSEN.DIAGNR
|
|
WHERE 1=1
|
|
AND DRG_ICD.FALL_DRGMCOID = w_rum.FALL_DRGMCOID
|
|
AND CATALOGDEF.SORTORDER = '01';
|
|
|
|
-- DR
|
|
UPDATE w_rum SET
|
|
diagnostic_principal_id = t_diagnostics.oid
|
|
FROM
|
|
prod_orbis.DRG_ICD
|
|
JOIN prod_orbis.CATALOGDEF ON CATALOGDEF.DBUID = DRG_ICD.DIAGNOSISTYPE
|
|
JOIN prod_orbis.DIAGNOSEN ON DIAGNOSEN.DIAGNOSEID = DRG_ICD.DIAGNOSEID
|
|
JOIN pmsi.t_diagnostics ON t_diagnostics.code = DIAGNOSEN.DIAGNR
|
|
WHERE 1=1
|
|
AND DRG_ICD.FALL_DRGMCOID = w_rum.FALL_DRGMCOID
|
|
AND CATALOGDEF.SORTORDER = '02';
|
|
|
|
|
|
INSERT INTO pmsi.p_rss_rum(
|
|
finess
|
|
,rss_id
|
|
,no_rss
|
|
,no_rum
|
|
,date_entree
|
|
,date_sortie
|
|
,mode_entree
|
|
,provenance
|
|
,mode_sortie
|
|
,destination
|
|
,duree_sejour
|
|
,nb_seances
|
|
,unite_medicale
|
|
,diagnostic_principal_id
|
|
,diagnostic_relie_id
|
|
,unite_medicale_id
|
|
,type_autorisation
|
|
,igs2
|
|
,type_autorisation_lit_dedie
|
|
,supplement_code)
|
|
SELECT
|
|
w_rss.finess as finess
|
|
,w_rss.rss_id
|
|
,w_rss.no_rss
|
|
,w_rum.WRUM_NUMERO as no_rum
|
|
,w_rum.STAYBEGIN as date_entree
|
|
,w_rum.STAYEND as date_fin
|
|
,w_rum.ADMISSIONTYPE as mode_entree
|
|
,w_rum.ORIGIN as provenance
|
|
,w_rum.DISCHARGETYPE as mode_sortie
|
|
,w_rum.DESTINATION as destination
|
|
,w_rum.STAYEND - w_rum.STAYBEGIN as duree_sejour
|
|
,w_rum.STAYNR as nb_seances
|
|
,COALESCE(t_unites_medicales.code, ''::text) as unite_medicale
|
|
,w_rum.diagnostic_principal_id as diagnostic_principal_id
|
|
,w_rum.diagnostic_relie_id as diagnostic_relie_id
|
|
,COALESCE(t_unites_medicales.oid, 0) as unite_medicale_id
|
|
,w_rum.AUTHORISATIONUM as type_autorisation
|
|
,base.cti_to_number(w_rum.IGS2) as igs2
|
|
,w_rum.AUTHORISATIONBED as type_autorisation_lit_dedie
|
|
,''::text as supplement_code
|
|
FROM w_rum
|
|
JOIN w_rss ON w_rss.no_rss = w_rum.no_rss
|
|
LEFT JOIN pmsi.t_unites_medicales ON t_unites_medicales.code = w_rum.UMNR;
|
|
|
|
-- comptage du nombre de rums
|
|
DROP TABLE IF EXISTS w_rss_rum;
|
|
CREATE TEMP TABLE w_rss_rum AS
|
|
SELECT
|
|
p_rss_rum.rss_id
|
|
,count(*) AS nb_rum
|
|
,MIN(p_rss_rum.no_rum) AS no_premier_rum
|
|
,MAX(p_rss_rum.no_rum) AS no_dernier_rum
|
|
FROM pmsi.p_rss_rum JOIN pmsi.p_rss ON p_rss.oid = p_rss_rum.rss_id
|
|
WHERE p_rss.en_cours = '1'
|
|
GROUP BY 1;
|
|
|
|
UPDATE pmsi.p_rss
|
|
SET
|
|
nb_rum = w_rss_rum.nb_rum
|
|
FROM
|
|
w_rss_rum
|
|
WHERE
|
|
w_rss_rum.rss_id = p_rss.oid;
|
|
|
|
-- unite principale et numero du rum principal
|
|
UPDATE pmsi.p_rss
|
|
SET
|
|
no_rum_principal = p_rss_rum.no_rum,
|
|
unite_medicale_principale_id = p_rss_rum.unite_medicale_id
|
|
FROM
|
|
pmsi.p_rss_rum
|
|
JOIN w_rum ON w_rum.rss_id = p_rss_rum.rss_id AND w_rum.WRUM_NUMERO = p_rss_rum.no_rum
|
|
WHERE 1=1
|
|
AND p_rss.oid = p_rss_rum.rss_id
|
|
AND w_rum.IS_MAINRUM = '1';
|
|
|
|
|
|
-- ME/PROV/MS/DEST
|
|
UPDATE pmsi.p_rss
|
|
SET
|
|
mode_entree = p_rss_rum.mode_entree,
|
|
provenance = p_rss_rum.provenance,
|
|
mode_sortie = p_rss_rum.mode_sortie,
|
|
destination = p_rss_rum.destination
|
|
FROM w_rss_rum, pmsi.p_rss_rum
|
|
WHERE p_rss.oid = w_rss_rum.rss_id AND p_rss.en_cours = '1' AND
|
|
p_rss_rum.rss_id = w_rss_rum.rss_id AND p_rss_rum.no_rum = w_rss_rum.no_premier_rum;
|
|
|
|
|
|
UPDATE pmsi.p_rss
|
|
SET
|
|
mode_sortie = p_rss_rum.mode_sortie,
|
|
destination = p_rss_rum.destination
|
|
FROM w_rss_rum, pmsi.p_rss_rum
|
|
WHERE p_rss.oid = w_rss_rum.rss_id AND p_rss.en_cours = '1' AND p_rss.nb_rum > 1 AND
|
|
p_rss_rum.rss_id = w_rss_rum.rss_id AND p_rss_rum.no_rum = w_rss_rum.no_dernier_rum;
|
|
|
|
]]></sqlcmd>
|
|
</NODE>
|
|
<NODE label="Diagnostics">
|
|
<sqlcmd><![CDATA[
|
|
|
|
INSERT INTO pmsi.p_rss_diagnostics (
|
|
finess
|
|
,no_rss
|
|
,no_rum
|
|
,diagnostic_id
|
|
,type_diagnostic
|
|
,type_diagnostic_rss
|
|
,imprecis
|
|
,unite_medicale
|
|
,rss_id
|
|
,unite_medicale_id
|
|
)
|
|
SELECT
|
|
w_finess.code as finess
|
|
,w_rum.no_rss as no_rss
|
|
,w_rum.WRUM_NUMERO as no_rum
|
|
,COALESCE(t_diagnostics.oid, 0) as diagnostic_id
|
|
,CASE
|
|
WHEN CATALOGDEF.SORTORDER = '01' THEN 'DP'
|
|
WHEN CATALOGDEF.SORTORDER = '02' THEN 'DR'
|
|
WHEN CATALOGDEF.SORTORDER = '06' THEN 'DA'
|
|
WHEN CATALOGDEF.SORTORDER = '07' THEN 'DD'
|
|
ELSE 'DA' END as type_diagnostic
|
|
,CASE
|
|
WHEN w_rum.IS_MAINRUM = '1' AND CATALOGDEF.SORTORDER = '01' THEN 'DP'
|
|
WHEN w_rum.IS_MAINRUM = '1' AND CATALOGDEF.SORTORDER = '02' THEN 'DR'
|
|
ELSE 'DA' END AS type_diagnostic_rss
|
|
,''::CHARACTER(1) as imprecis
|
|
,w_rum.UMNR as unite_medicale
|
|
,w_rum.rss_id as rss_id
|
|
,COALESCE(t_unites_medicales.oid, 0) as unite_medicale_id
|
|
FROM
|
|
w_finess,
|
|
w_rum
|
|
JOIN prod_orbis.DRG_ICD ON DRG_ICD.FALL_DRGMCOID = w_rum.FALL_DRGMCOID
|
|
JOIN prod_orbis.DIAGNOSEN ON DIAGNOSEN.DIAGNOSEID = DRG_ICD.DIAGNOSEID
|
|
JOIN prod_orbis.CATALOGDEF ON CATALOGDEF.DBUID = DRG_ICD.DIAGNOSISTYPE
|
|
LEFT JOIN pmsi.t_unites_medicales ON t_unites_medicales.code = w_rum.UMNR
|
|
LEFT JOIN pmsi.t_diagnostics ON t_diagnostics.code = DIAGNOSEN.DIAGNR
|
|
ORDER BY w_rum.no_rss, w_rum.WRUM_NUMERO;
|
|
|
|
]]></sqlcmd>
|
|
</NODE>
|
|
<NODE label="Actes">
|
|
<sqlcmd><![CDATA[
|
|
|
|
INSERT INTO pmsi.p_rss_actes(
|
|
finess
|
|
,rss_id
|
|
,no_rss
|
|
,no_rum
|
|
,unite_medicale
|
|
,unite_medicale_id
|
|
,date_acte
|
|
,medecin_id
|
|
,acte_id
|
|
,nombre
|
|
,phase_ccam
|
|
,activite_ccam
|
|
,extension_ccam
|
|
,modificateur_ccam_1
|
|
,modificateur_ccam_2
|
|
,modificateur_ccam_3
|
|
,modificateur_ccam_4
|
|
,remboursement_excp_ccam
|
|
,association_nonprevue_ccam
|
|
,condition_gm_ok
|
|
)
|
|
SELECT
|
|
w_finess.code as finess
|
|
,w_rum.rss_id
|
|
,w_rum.no_rss as no_rss
|
|
,w_rum.WRUM_NUMERO as no_rum
|
|
,w_rum.UMNR as unite_medicale
|
|
,COALESCE(t_unites_medicales.oid, 0) as unite_medicale_id
|
|
,date(DRG_ACTS.DATEACT) as date_acte
|
|
,COALESCE(t_medecins.oid, 0) as medecin_id
|
|
,COALESCE(t_actes.oid, 0) as acte_id
|
|
,DRG_ACTS.EXECUTIONS as nombre
|
|
,DRG_ACTS.PHASE as phase_ccam
|
|
,DRG_ACTS.ACTIVITY as activite_ccam
|
|
,DRG_ACTS.EXTDOC AS extension_ccam
|
|
,CASE WHEN substr(DRG_ACTS.MODIFIER, 1,1) != ''::text THEN substr(DRG_ACTS.MODIFIER, 1, 1) ELSE ''::text END as modificateur_ccam_1
|
|
,CASE WHEN substr(DRG_ACTS.MODIFIER, 2,1) != ''::text THEN substr(DRG_ACTS.MODIFIER, 2, 1) ELSE ''::text END as modificateur_ccam_2
|
|
,CASE WHEN substr(DRG_ACTS.MODIFIER, 3,1) != ''::text THEN substr(DRG_ACTS.MODIFIER, 3, 1) ELSE ''::text END as modificateur_ccam_3
|
|
,CASE WHEN substr(DRG_ACTS.MODIFIER, 4,1) != ''::text THEN substr(DRG_ACTS.MODIFIER, 4, 1) ELSE ''::text END as modificateur_ccam_4
|
|
,DRG_ACTS.RBSEXCEP as remboursement_excp_ccam
|
|
,DRG_ACTS.ASSOCIATION as association_non_prevue_ccam
|
|
,'0'::character(1) as condition_gm_ok
|
|
FROM
|
|
w_finess,
|
|
w_rum
|
|
JOIN prod_orbis.DRG_ACTS ON DRG_ACTS.FALL_DRGMCOID = w_rum.FALL_DRGMCOID
|
|
JOIN prod_orbis.EXTERNALSERVICE ON EXTERNALSERVICE.EXTERNALSERVICEID = DRG_ACTS.LSTID
|
|
LEFT JOIN pmsi.t_unites_medicales ON t_unites_medicales.code = w_rum.UMNR
|
|
LEFT JOIN pmsi.t_medecins ON t_medecins.code = DRG_ACTS.EXECUTIONUSER
|
|
LEFT JOIN pmsi.t_actes ON t_actes.code = EXTERNALSERVICE.TW_LSTNR
|
|
ORDER BY w_rum.no_rss, w_rum.WRUM_NUMERO;
|
|
|
|
]]></sqlcmd>
|
|
</NODE>
|
|
|
|
</NODE>
|
|
<NODE name="PMSIETAT" label="RECUPERATION ETAT DES DOSSIERS">
|
|
|
|
<NODE label="Initialisation">
|
|
<sqlcmd><![CDATA[
|
|
|
|
-- Séjours non groupés
|
|
INSERT INTO pmsi.t_ghm(
|
|
code,
|
|
texte,
|
|
mco,
|
|
aso,
|
|
severite,
|
|
cmd_id,
|
|
ghm5_id,
|
|
ligne_oap_id,
|
|
cas_id)
|
|
SELECT
|
|
'99Z99Z' AS code,
|
|
'Séjours sortis non groupés' AS texte,
|
|
'?' AS mco,
|
|
'?' AS aso,
|
|
'Z' AS severite,
|
|
COALESCE((SELECT oid FROM pmsi.t_cmd WHERE code = '99'),0) AS cmd_id,
|
|
COALESCE((SELECT oid FROM pmsi.t_ghm5 WHERE code = '99Z99'),0) AS ghm5_id,
|
|
0 AS ligne_oap_id,
|
|
COALESCE((SELECT oid FROM base.t_cas WHERE code = '?'),0) AS cas_id
|
|
WHERE '99Z99Z' NOT IN (SELECT code FROM pmsi.t_ghm)
|
|
UNION
|
|
SELECT
|
|
'99Z98Z' AS code,
|
|
'GHM indisponible' AS texte,
|
|
'?' AS mco,
|
|
'?' AS aso,
|
|
'Z' AS severite,
|
|
COALESCE((SELECT oid FROM pmsi.t_cmd WHERE code = '99'),0) AS cmd_id,
|
|
COALESCE((SELECT oid FROM pmsi.t_ghm5 WHERE code = '99Z98'),0) AS ghm5_id,
|
|
0 AS ligne_oap_id,
|
|
COALESCE((SELECT oid FROM base.t_cas WHERE code = '?'),0) AS cas_id
|
|
WHERE '99Z98Z' NOT IN (SELECT code FROM pmsi.t_ghm);
|
|
|
|
|
|
|
|
SELECT pmsi.cti_initialize_rss_etat();
|
|
|
|
]]></sqlcmd>
|
|
</NODE>
|
|
|
|
<NODE label="Etat des dossiers">
|
|
<sqlcmd><![CDATA[
|
|
|
|
|
|
--UPDATE pmsi.p_rss_etat
|
|
--SET
|
|
-- est_groupe = CASE WHEN w_rss.DRGGHM = '99Z99Z' THEN '0'
|
|
-- WHEN w_rss.IS_GROUPED = '1' THEN '1'
|
|
-- ELSE '0' END
|
|
-- ,date_groupage = COALESCE(w_rss.VALIDATION_LASTDATE, '20991231'::date)
|
|
-- --,est_facture = CASE WHEN w_rss.IS_FACTURED IN ('1', '2', '3') THEN '1' ELSE '0' END
|
|
--FROM w_rss
|
|
--WHERE p_rss_etat.rss_id = w_rss.rss_id;
|
|
--
|
|
--
|
|
--UPDATE pmsi.p_rss
|
|
--SET
|
|
-- en_cours_etat = 'S'
|
|
--FROM
|
|
-- pmsi.t_ghm
|
|
--WHERE
|
|
-- p_rss.ghm_id = t_ghm.oid
|
|
-- AND t_ghm.code = '99Z99Z'
|
|
-- AND en_cours = '1'
|
|
-- AND en_cours_etat = 'G';
|
|
|
|
]]></sqlcmd>
|
|
</NODE>
|
|
|
|
</NODE>
|
|
|
|
</ROOT>
|