pour déploiement auto v2 via gitlab
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.
 
 

2123 lines
71 KiB

<?xml version="1.0" encoding="ISO-8859-1"?>
<ROOT>
<NODE name="PMSICOMPLEMENTS" label="RECUPERATION DES DONNEES COMPLEMENTAIRES PMSI">
<NODE label="Paramètres">
<sqlcmd><![CDATA[
INSERT INTO pmsi.t_medecins(code, nom, prenom, specialite_id, no_adeli, specialite_interne_id)
SELECT
trim(to_char(MDPRAT,'0000')),
MDNOMS,
MDPRES,
COALESCE(t_specialites_medecin.oid,0),
MDNIOM,
COALESCE(t_specialites_internes_medecin.oid,0)
FROM prod_shs.[ACTIVITESCHEMA]_MDP01
LEFT JOIN pmsi.t_specialites_medecin ON (t_specialites_medecin.code = SUBSTR(MDZTAR , 1, 2))
LEFT JOIN pmsi.t_specialites_internes_medecin ON (t_specialites_internes_medecin.code = SUBSTR(MDZTAR , 1, 2) || '..')
LEFT JOIN pmsi.t_medecins ON (trim(to_char(MDPRAT,'0000')) = t_medecins.code)
WHERE 1=1
AND trim(to_char(MDPRAT,'0000')) IN
(
SELECT
CASE
WHEN L0CCHI <> '' AND L0CCHI <> '0000' THEN L0CCHI
WHEN L0CSPE <> '' AND L0CSPE <> '0000' THEN L0CSPE
WHEN L0CME1 <> '' AND L0CME1 <> '0000' THEN L0CME1
ELSE L0CANE
END
FROM prod_shs.[PMSISCHEMA]_L0P01
WHERE L0AASO >= 2008
GROUP BY 1
)
AND t_medecins.code IS NULL
;
INSERT INTO pmsi.t_medecins(code, nom, prenom, specialite_id, no_adeli, specialite_interne_id)
SELECT
trim(to_char(MDPRAT,'0000')),
MDNOMS,
MDPRES,
COALESCE(t_specialites_medecin.oid,0),
MDNIOM,
COALESCE(t_specialites_internes_medecin.oid,0)
FROM prod_shs.[ACTIVITESCHEMA]_MDP01
LEFT JOIN pmsi.t_specialites_medecin ON (t_specialites_medecin.code = SUBSTR(MDZTAR , 1, 2))
LEFT JOIN pmsi.t_specialites_internes_medecin ON (t_specialites_internes_medecin.code = SUBSTR(MDZTAR , 1, 2) || '..')
LEFT JOIN pmsi.t_medecins ON (trim(to_char(MDPRAT,'0000')) = t_medecins.code)
WHERE 1=1
AND trim(to_char(MDPRAT,'0000')) IN
(
SELECT
L5CMED
FROM prod_shs.[PMSISCHEMA]_L5P01
WHERE L5ANNE >= 2008
GROUP BY 1
)
AND t_medecins.code IS NULL
;
]]></sqlcmd>
</NODE>
<NODE label="Identités">
<sqlcmd><![CDATA[
UPDATE [SCHEMA].p_rss
SET no_patient = L0DMED
FROM prod_shs.[PMSISCHEMA]_L0P01
WHERE p_rss.no_rss = L0NRSS AND
date_part('year', p_rss.date_sortie) = L0AASO AND
date_part('month', p_rss.date_sortie) = L0MMSO AND
no_patient IS DISTINCT FROM L0DMED;
UPDATE [SCHEMA].p_rss
SET no_sejour_administratif = to_char(L0NDOS,'FM00000000')
FROM prod_shs.[PMSISCHEMA]_L0P01
WHERE p_rss.no_rss = L0NRSS AND
ghm_id = 0 AND
date_part('year', p_rss.date_sortie) = L0AASO AND
date_part('month', p_rss.date_sortie) = L0MMSO AND
no_sejour_administratif IS DISTINCT FROM to_char(L0NDOS,'FM00000000');
UPDATE [SCHEMA].p_identites
SET nom = L0NOMP,
prenom = L0PREP,
nom_naissance = DMNJFM
FROM [SCHEMA].p_rss
JOIN prod_shs.[PMSISCHEMA]_L0P01 ON p_rss.no_rss = L0NRSS AND
date_part('year', p_rss.date_sortie) = L0AASO AND
date_part('month', p_rss.date_sortie) = L0MMSO
JOIN prod_shs.[ACTIVITESCHEMA]_dmp01 ON L0DMED = DMDMED
WHERE p_identites.rss_id = p_rss.oid AND
(
nom IS DISTINCT FROM L0NOMP OR
prenom IS DISTINCT FROM L0PREP OR
nom_naissance IS DISTINCT FROM DMNJFM
);
-- Externes SHS qui ne sont pas dans PMSI
-- no_sejour_admin ok => formatage
UPDATE [SCHEMA].p_rss
SET no_sejour_administratif = to_char(ADDOSS,'FM00000000')
FROM prod_shs.[ACTIVITESCHEMA]_ADP01
WHERE substr(no_sejour_administratif,1,8) = ADDOSS AND
ghm_id = 0 AND
to_char(p_rss.date_sortie,'YYYYMMDD') = ADDTS1 AND
to_char(p_rss.date_naissance,'DDMMYYYY') = to_char(ADDTNM,'FM00000000') AND
no_sejour_administratif IS DISTINCT FROM to_char(ADDOSS,'FM00000000') ;
-- à partir des numeros de facture
UPDATE [SCHEMA].p_rss
SET no_sejour_administratif = to_char(ADDOSS,'FM00000000')
FROM prod_shs.[ACTIVITESCHEMA]_ADP01
JOIN prod_shs.[ACTIVITESCHEMA]_FDP02 ON ADDOSS = FDDOSS AND ADDCPL = FDDCPL
WHERE FDNFA1 LIKE '%'|| no_sejour_administratif AND
ghm_id = 0 AND
to_char(p_rss.date_sortie,'YYYYMMDD') = ADDTS1 AND
to_char(p_rss.date_naissance,'DDMMYYYY') = to_char(ADDTNM,'FM00000000') AND
no_sejour_administratif IS DISTINCT FROM to_char(ADDOSS,'FM00000000') ;
-- a partir des dates d'entrée, sortie et naissance (si pas plusieurs séjours avec ces mêmes infos)
UPDATE [SCHEMA].p_rss
SET no_sejour_administratif = to_char(ADDOSS,'FM00000000')
FROM prod_shs.[ACTIVITESCHEMA]_ADP01
LEFT JOIN (
SELECT ENT, SOR, DN FROM (
SELECT ADDTE1 as ENT, ADDTS1 AS SOR, ADDTNM AS DN, ADNOM1, ADPREM FROM prod_shs.[ACTIVITESCHEMA]_ADP01 GROUP BY 1, 2, 3, 4, 5
) sub
GROUP BY 1, 2, 3
HAVING count(*) > 1
) sub2
ON ENT = ADDTE1 AND SOR = ADDTS1 AND DN = ADDTNM
WHERE
ENT IS NULL AND
ghm_id = 0 AND
to_char(p_rss.date_entree,'YYYYMMDD') = ADDTE1 AND
to_char(p_rss.date_sortie,'YYYYMMDD') = ADDTS1 AND
to_char(p_rss.date_naissance,'DDMMYYYY') = to_char(ADDTNM,'FM00000000') AND
no_sejour_administratif IS DISTINCT FROM to_char(ADDOSS,'FM00000000') ;
-- a partir de l'historique
UPDATE [SCHEMA].p_rss
SET no_sejour_administratif = to_char(ADDOSS,'FM00000000')
FROM prod_shs.[ACTIVITESCHEMA]H_ADP01H
LEFT JOIN (
SELECT ENT, SOR, DN FROM (
SELECT ADDTE1 as ENT, ADDTS1 AS SOR, ADDTNM AS DN, ADNOM1, ADPREM FROM prod_shs.[ACTIVITESCHEMA]H_ADP01H GROUP BY 1, 2, 3, 4, 5
) sub
GROUP BY 1, 2, 3
HAVING count(*) > 1
) sub2
ON ENT = ADDTE1 AND SOR = ADDTS1 AND DN = ADDTNM
WHERE
ENT IS NULL AND
ghm_id = 0 AND
to_char(p_rss.date_entree,'YYYYMMDD') = ADDTE1 AND
to_char(p_rss.date_sortie,'YYYYMMDD') = ADDTS1 AND
to_char(p_rss.date_naissance,'DDMMYYYY') = to_char(ADDTNM,'FM00000000') AND
no_sejour_administratif IS DISTINCT FROM to_char(ADDOSS,'FM00000000') ;
UPDATE [SCHEMA].p_identites
SET nom = ADNOM1,
prenom = ADPREM
FROM [SCHEMA].p_rss
JOIN prod_shs.[ACTIVITESCHEMA]H_adp01H ON no_sejour_administratif = ADDOSS AND
to_char(p_rss.date_sortie,'YYYYMMDD') = ADDTS1 AND
to_char(p_rss.date_naissance,'DDMMYYYY') = to_char(ADDTNM,'FM00000000')
WHERE p_identites.rss_id = p_rss.oid AND
nom LIKE 'RSS %';
UPDATE [SCHEMA].p_rss
SET no_patient = ADDMED
FROM prod_shs.[ACTIVITESCHEMA]H_adp01H
WHERE no_sejour_administratif = ADDOSS AND
to_char(p_rss.date_sortie,'YYYYMMDD') = ADDTS1 AND
to_char(p_rss.date_naissance,'DDMMYYYY') = to_char(ADDTNM,'FM00000000') AND
no_patient <= 0;
UPDATE [SCHEMA].p_identites
SET nom = ADNOM1,
prenom = ADPREM
FROM [SCHEMA].p_rss
JOIN prod_shs.[ACTIVITESCHEMA]_adp01 ON no_sejour_administratif = ADDOSS AND
to_char(p_rss.date_sortie,'YYYYMMDD') = ADDTS1 AND
to_char(p_rss.date_naissance,'DDMMYYYY') = to_char(ADDTNM,'FM00000000')
WHERE p_identites.rss_id = p_rss.oid AND
nom LIKE 'RSS %';
UPDATE [SCHEMA].p_rss
SET no_patient = ADDMED
FROM prod_shs.[ACTIVITESCHEMA]_adp01
WHERE no_sejour_administratif = ADDOSS AND
to_char(p_rss.date_sortie,'YYYYMMDD') = ADDTS1 AND
to_char(p_rss.date_naissance,'DDMMYYYY') = to_char(ADDTNM,'FM00000000') AND
no_patient <= 0;
]]></sqlcmd>
</NODE>
<NODE label="Médecins RSS">
<sqlcmd><![CDATA[
-- Liaison via le n° séjour PMSI.
UPDATE [SCHEMA].p_rss
SET medecin_rss_id = t_medecins.oid
FROM prod_shs.[PMSISCHEMA]_L0P01
JOIN pmsi.t_medecins ON
CASE
WHEN L0CCHI <> '' AND L0CCHI <> '0000' THEN L0CCHI
WHEN L0CSPE <> '' AND L0CSPE <> '0000' THEN L0CSPE
WHEN L0CME1 <> '' AND L0CME1 <> '0000' THEN L0CME1
ELSE L0CANE
END = t_medecins.code
WHERE 1=1
AND p_rss.no_rss = L0NRSS
AND p_rss.import_id = [IMPORT_ID]
AND date_part('year', p_rss.date_sortie) = L0AASO
AND medecin_rss_id IS DISTINCT FROM t_medecins.oid
;
-- Tentative de liaison via le n° administratif de séjour.
UPDATE [SCHEMA].p_rss
SET medecin_rss_id = t_medecins.oid
FROM prod_shs.[PMSISCHEMA]_L0P01
JOIN pmsi.t_medecins ON
CASE
WHEN L0CCHI <> '' AND L0CCHI <> '0000' THEN L0CCHI
WHEN L0CSPE <> '' AND L0CSPE <> '0000' THEN L0CSPE
WHEN L0CME1 <> '' AND L0CME1 <> '0000' THEN L0CME1
ELSE L0CANE
END = t_medecins.code
WHERE 1=1
AND p_rss.no_sejour_administratif = L0NDOS
AND p_rss.import_id = [IMPORT_ID]
AND to_char(p_rss.date_sortie, 'YYYYMM') = to_char(L0AASO,'FM0000')||to_char(L0MMSO,'FM00')
AND medecin_rss_id IS DISTINCT FROM t_medecins.oid
;
-- Liaison via la gestion administrative (externes)
UPDATE [SCHEMA].p_rss
SET medecin_rss_id = t_medecins.oid
FROM prod_shs.[ACTIVITESCHEMA]_adp01
JOIN pmsi.t_medecins ON to_char(ADMEDR,'FM0000') = t_medecins.code
WHERE 1=1
AND p_rss.no_sejour_administratif = ADDOSS AND ADDCPL = 0
AND p_rss.import_id = [IMPORT_ID]
AND to_char(p_rss.date_sortie,'YYYYMMDD') = ADDTS1
AND to_char(p_rss.date_naissance,'DDMMYYYY') = to_char(ADDTNM,'FM00000000')
AND medecin_rss_id = 0
;
]]></sqlcmd>
</NODE>
<NODE label="Médecins actes">
<sqlcmd><![CDATA[
DROP TABLE IF EXISTS w_L5P01;
CREATE TEMP TABLE w_L5P01 AS
SELECT
L5NDOS
,L5COMP
,L5FI12
,L5ANNE
,L5MOIS
,L5JOUR
,L5CMED
,L5CDAD
FROM
prod_shs.[PMSISCHEMA]_L5P01
WHERE
L5CNOM = 'CCAM';
DROP TABLE IF EXISTS w_actes;
CREATE TEMP TABLE w_actes AS
SELECT
oid::bigint
,code::text
FROM pmsi.t_actes;
DROP TABLE IF EXISTS w_medecins;
CREATE TEMP TABLE w_medecins AS
SELECT
oid::bigint
,code::text
FROM pmsi.t_medecins;
DROP TABLE IF EXISTS w_rss;
CREATE TEMP TABLE w_rss AS
SELECT
no_rss::numeric
,date_part('year', p_rss.date_sortie)::numeric as date_sortie
,to_char(p_rss.date_sortie, 'YYYYMM')::text as date_sortie_text
,oid::bigint
,no_sejour_administratif::numeric
FROM [SCHEMA].p_rss
WHERE
import_id = [IMPORT_ID]
;
CREATE INDEX w_rss_i1 ON w_rss USING btree (oid);
CREATE INDEX w_rss_i2 ON w_rss USING btree (no_rss);
CREATE INDEX w_rss_i3 ON w_rss USING btree (date_sortie);
CREATE INDEX w_rss_i4 ON w_rss USING btree (no_sejour_administratif);
CREATE INDEX w_medecins_i1 ON w_medecins USING btree (oid);
CREATE INDEX w_medecins_i2 ON w_medecins USING btree (code);
CREATE INDEX w_actes_i1 ON w_actes USING btree (oid);
CREATE INDEX w_actes_i2 ON w_actes USING btree (code);
CREATE INDEX w_L5P01_i1 ON w_L5P01 USING btree (L5CMED);
CREATE INDEX w_L5P01_i2 ON w_L5P01 USING btree (L5CDAD);
CREATE INDEX w_L5P01_i3 ON w_L5P01 USING btree (L5NDOS);
-- Liaison via le n° séjour PMSI.
UPDATE [SCHEMA].p_rss_actes
SET medecin_id = w_medecins.oid
FROM prod_shs.[PMSISCHEMA]_L0P01
JOIN w_rss ON 1=1
AND w_rss.no_rss = L0NRSS
AND w_rss.date_sortie = L0AASO
JOIN w_L5P01 ON 1=1
AND L5NDOS = L0NDOS
AND L5COMP = L0COMP
JOIN w_medecins ON L5CMED = w_medecins.code
JOIN w_actes ON L5CDAD = w_actes.code
WHERE 1=1
AND p_rss_actes.rss_id = w_rss.oid
AND p_rss_actes.acte_id = w_actes.oid
AND p_rss_actes.activite_ccam = L5FI12
AND p_rss_actes.date_acte = base.cti_to_date(L5ANNE, L5MOIS, L5JOUR)
AND p_rss_actes.medecin_id IS DISTINCT FROM w_medecins.oid
;
-- Tentative de liaison via le n° administratif de séjour.
UPDATE [SCHEMA].p_rss_actes
SET medecin_id = w_medecins.oid
FROM prod_shs.[PMSISCHEMA]_L0P01
JOIN w_rss ON 1=1
AND w_rss.no_sejour_administratif = L0NDOS
AND w_rss.date_sortie_text = to_char(L0AASO,'FM0000')||to_char(L0MMSO,'FM00')
AND w_rss.date_sortie = L0AASO
JOIN w_L5P01 ON 1=1
AND L5NDOS = L0NDOS
AND L5COMP = L0COMP
JOIN w_medecins ON L5CMED = w_medecins.code
JOIN w_actes ON L5CDAD = w_actes.code
WHERE 1=1
AND p_rss_actes.rss_id = w_rss.oid
AND p_rss_actes.acte_id = w_actes.oid
AND p_rss_actes.activite_ccam = L5FI12
AND p_rss_actes.date_acte = base.cti_to_date(L5ANNE, L5MOIS, L5JOUR)
AND p_rss_actes.medecin_id IS DISTINCT FROM w_medecins.oid
;
-- Liaison par les actes Activité s'il reste des exécutants non renseignés
UPDATE [SCHEMA].p_rss_actes SET
medecin_id = COALESCE(w_medecins.oid, 0)
FROM
prod_shs.[ACTIVITESCHEMA]_MFP01ccam
JOIN w_rss ON MFDOSS = no_sejour_administratif AND MFDCPL = 0
JOIN w_actes ON MFCCAM = w_actes.code
LEFT JOIN w_medecins ON to_char(MFRUPR,'FM0000') = w_medecins.code
WHERE 1=1
AND p_rss_actes.rss_id = w_rss.oid
AND p_rss_actes.acte_id = w_actes.oid
AND p_rss_actes.medecin_id = 0
AND p_rss_actes.date_acte = to_date(MFDTA1::text, 'YYYYMMDD')
AND p_rss_actes.activite_ccam = MFCCAC;
UPDATE [SCHEMA].p_rss_actes SET
medecin_id = COALESCE(w_medecins.oid, 0)
FROM
prod_shs.[ACTIVITESCHEMA]h_MFP01ccamh
JOIN w_rss ON MFDOSS = no_sejour_administratif AND MFDCPL = 0
JOIN w_actes ON MFCCAM = w_actes.code
LEFT JOIN w_medecins ON to_char(MFRUPR,'FM0000') = w_medecins.code
WHERE 1=1
AND p_rss_actes.rss_id = w_rss.oid
AND p_rss_actes.acte_id = w_actes.oid
AND p_rss_actes.medecin_id = 0
AND p_rss_actes.date_acte = to_date(MFDTA1::text, 'YYYYMMDD')
AND p_rss_actes.activite_ccam = MFCCAC;
DROP TABLE IF EXISTS w_L5P01;
DROP TABLE IF EXISTS w_rss;
DROP TABLE IF EXISTS w_medecins;
DROP TABLE IF EXISTS w_actes;
]]></sqlcmd>
</NODE>
<NODE label="Unités médicales Externes">
<sqlcmd><![CDATA[
-- Séjours actifs
DROP TABLE IF EXISTS w_ext_um;
CREATE TEMP TABLE w_ext_um AS
SELECT p_rss.oid AS rss_id, ADCSER, 0::bigint AS unite_medicale_id
FROM [SCHEMA].p_rss
JOIN prod_shs.[ACTIVITESCHEMA]_ADP01 ON no_sejour_administratif = ADDOSS AND ADDCPL = 0
WHERE unite_medicale_principale_id = 0 AND
p_rss.ghm_id = 0 AND
to_char(p_rss.date_sortie,'YYYYMMDD') = ADDTS1 AND
to_char(p_rss.date_naissance,'DDMMYYYY') = to_char(ADDTNM,'FM00000000') ;
INSERT INTO pmsi.t_unites_medicales (code, texte)
SELECT ADCSER, SFINT5
FROM w_ext_um
JOIN prod_shs.[ACTIVITESCHEMA]_SFP01 ON ADCSER = SFCSER
WHERE ADCSER NOT IN (SELECT code FROM pmsi.t_unites_medicales)
GROUP BY 1,2;
UPDATE w_ext_um
SET unite_medicale_id = t_unites_medicales.oid
FROM pmsi.t_unites_medicales
WHERE ADCSER = t_unites_medicales.code;
UPDATE [SCHEMA].p_rss
SET unite_medicale_principale_id = unite_medicale_id
FROM w_ext_um
WHERE p_rss.oid = w_ext_um.rss_id;
UPDATE [SCHEMA].p_rss_rum
SET unite_medicale_id = w_ext_um.unite_medicale_id, unite_medicale = ADCSER
FROM w_ext_um
WHERE p_rss_rum.rss_id = w_ext_um.rss_id;
UPDATE [SCHEMA].p_rss_actes
SET unite_medicale_id = w_ext_um.unite_medicale_id, unite_medicale = ADCSER
FROM w_ext_um
WHERE p_rss_actes.rss_id = w_ext_um.rss_id;
UPDATE [SCHEMA].p_rss_diagnostics
SET unite_medicale_id = w_ext_um.unite_medicale_id, unite_medicale = ADCSER
FROM w_ext_um
WHERE p_rss_diagnostics.rss_id = w_ext_um.rss_id;
-- Séjours historique
DROP TABLE IF EXISTS w_ext_um;
CREATE TEMP TABLE w_ext_um AS
SELECT p_rss.oid AS rss_id, ADCSER, 0::bigint AS unite_medicale_id
FROM [SCHEMA].p_rss
JOIN prod_shs.[ACTIVITESCHEMA]_ADP01 ON no_sejour_administratif = ADDOSS AND ADDCPL = 0
WHERE unite_medicale_principale_id = 0 AND
p_rss.ghm_id = 0 AND
to_char(p_rss.date_sortie,'YYYYMMDD') = ADDTS1 AND
to_char(p_rss.date_naissance,'DDMMYYYY') = to_char(ADDTNM,'FM00000000') ;
INSERT INTO pmsi.t_unites_medicales (code, texte)
SELECT ADCSER, SFINT5
FROM w_ext_um
JOIN prod_shs.[ACTIVITESCHEMA]_SFP01 ON ADCSER = SFCSER
WHERE ADCSER NOT IN (SELECT code FROM pmsi.t_unites_medicales)
GROUP BY 1,2;
UPDATE w_ext_um
SET unite_medicale_id = t_unites_medicales.oid
FROM pmsi.t_unites_medicales
WHERE ADCSER = t_unites_medicales.code;
UPDATE [SCHEMA].p_rss
SET unite_medicale_principale_id = unite_medicale_id
FROM w_ext_um
WHERE p_rss.oid = w_ext_um.rss_id;
UPDATE [SCHEMA].p_rss_rum
SET unite_medicale_id = w_ext_um.unite_medicale_id, unite_medicale = ADCSER
FROM w_ext_um
WHERE p_rss_rum.rss_id = w_ext_um.rss_id;
UPDATE [SCHEMA].p_rss_actes
SET unite_medicale_id = w_ext_um.unite_medicale_id, unite_medicale = ADCSER
FROM w_ext_um
WHERE p_rss_actes.rss_id = w_ext_um.rss_id;
UPDATE [SCHEMA].p_rss_diagnostics
SET unite_medicale_id = w_ext_um.unite_medicale_id, unite_medicale = ADCSER
FROM w_ext_um
WHERE p_rss_diagnostics.rss_id = w_ext_um.rss_id;
-- Dossier en historique
DROP TABLE IF EXISTS w_ext_um;
CREATE TEMP TABLE w_ext_um AS
SELECT p_rss.oid AS rss_id, ADCSER, 0::bigint AS unite_medicale_id
FROM [SCHEMA].p_rss
JOIN prod_shs.[ACTIVITESCHEMA]H_ADP01H ON no_sejour_administratif = ADDOSS AND ADDCPL = 0
WHERE unite_medicale_principale_id = 0 AND
p_rss.ghm_id = 0 AND
to_char(p_rss.date_sortie,'YYYYMMDD') = ADDTS1 AND
to_char(p_rss.date_naissance,'DDMMYYYY') = to_char(ADDTNM,'FM00000000') ;
INSERT INTO pmsi.t_unites_medicales (code, texte)
SELECT ADCSER, SFINT5
FROM w_ext_um
JOIN prod_shs.[ACTIVITESCHEMA]_SFP01 ON ADCSER = SFCSER
WHERE ADCSER NOT IN (SELECT code FROM pmsi.t_unites_medicales)
GROUP BY 1,2;
UPDATE w_ext_um
SET unite_medicale_id = t_unites_medicales.oid
FROM pmsi.t_unites_medicales
WHERE ADCSER = t_unites_medicales.code;
UPDATE [SCHEMA].p_rss
SET unite_medicale_principale_id = unite_medicale_id
FROM w_ext_um
WHERE p_rss.oid = w_ext_um.rss_id;
UPDATE [SCHEMA].p_rss_rum
SET unite_medicale_id = w_ext_um.unite_medicale_id, unite_medicale = ADCSER
FROM w_ext_um
WHERE p_rss_rum.rss_id = w_ext_um.rss_id;
UPDATE [SCHEMA].p_rss_actes
SET unite_medicale_id = w_ext_um.unite_medicale_id, unite_medicale = ADCSER
FROM w_ext_um
WHERE p_rss_actes.rss_id = w_ext_um.rss_id;
UPDATE [SCHEMA].p_rss_diagnostics
SET unite_medicale_id = w_ext_um.unite_medicale_id, unite_medicale = ADCSER
FROM w_ext_um
WHERE p_rss_diagnostics.rss_id = w_ext_um.rss_id;
]]></sqlcmd>
</NODE>
</NODE>
<NODE name="PMSIENCOURS" label="RECUPERATION DES DOSSIERS PMSI EN-COURS SHS">
<NODE label="Médecins">
<sqlcmd><![CDATA[
INSERT INTO pmsi.t_medecins(code, nom, prenom, specialite_id, no_adeli, specialite_interne_id)
SELECT
trim(to_char(MDPRAT,'0000')),
MDNOMS,
MDPRES,
COALESCE(t_specialites_medecin.oid,0),
MDNIOM,
COALESCE(t_specialites_internes_medecin.oid,0)
FROM prod_shs.[ACTIVITESCHEMA]_MDP01
LEFT JOIN pmsi.t_specialites_medecin ON (t_specialites_medecin.code = SUBSTR(MDZTAR , 1, 2))
LEFT JOIN pmsi.t_specialites_internes_medecin ON (t_specialites_internes_medecin.code = SUBSTR(MDZTAR , 1, 2) || '..')
LEFT JOIN pmsi.t_medecins ON (trim(to_char(MDPRAT,'0000')) = t_medecins.code)
WHERE 1=1
AND trim(to_char(MDPRAT,'0000')) IN
(
SELECT
CASE
WHEN L0CCHI <> '' AND L0CCHI <> '0000' THEN L0CCHI
WHEN L0CSPE <> '' AND L0CSPE <> '0000' THEN L0CSPE
WHEN L0CME1 <> '' AND L0CME1 <> '0000' THEN L0CME1
ELSE L0CANE
END
FROM prod_shs.[PMSISCHEMA]_L0P01
WHERE L0AASO >= 2008
GROUP BY 1
)
AND t_medecins.code IS NULL
;
INSERT INTO pmsi.t_medecins(code, nom, prenom, specialite_id, no_adeli, specialite_interne_id)
SELECT
trim(to_char(MDPRAT,'0000')),
MDNOMS,
MDPRES,
COALESCE(t_specialites_medecin.oid,0),
MDNIOM,
COALESCE(t_specialites_internes_medecin.oid,0)
FROM prod_shs.[ACTIVITESCHEMA]_MDP01
LEFT JOIN pmsi.t_specialites_medecin ON (t_specialites_medecin.code = SUBSTR(MDZTAR , 1, 2))
LEFT JOIN pmsi.t_specialites_internes_medecin ON (t_specialites_internes_medecin.code = SUBSTR(MDZTAR , 1, 2) || '..')
LEFT JOIN pmsi.t_medecins ON (trim(to_char(MDPRAT,'0000')) = t_medecins.code)
WHERE 1=1
AND trim(to_char(MDPRAT,'0000')) IN
(
SELECT
L5CMED
FROM prod_shs.[PMSISCHEMA]_L5P01
WHERE L5ANNE >= 2008
GROUP BY 1
)
AND t_medecins.code IS NULL
;
]]></sqlcmd>
</NODE>
<NODE label="Autres paramètres">
<sqlcmd><![CDATA[
-- unités médicales
DROP TABLE IF EXISTS w_um;
CREATE TEMP TABLE w_um AS
SELECT
L2CDUM as code,
COALESCE(L3LBUM, '') AS texte
FROM
prod_shs.[PMSISCHEMA]_L2P01
LEFT JOIN prod_shs.[PMSISCHEMA]_L3P01 ON L3CDUM = L2CDUM
WHERE
L2CDUM <> ''
GROUP BY 1,2;
INSERT INTO pmsi.t_unites_medicales (code, texte)
SELECT
w_um.code,
w_um.texte
FROM w_um
WHERE
w_um.code NOT IN (SELECT code FROM pmsi.t_unites_medicales)
GROUP BY 1,2;
]]></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_rss;
CREATE TEMP TABLE w_rss AS
SELECT
(SELECT code FROM w_finess) AS finess,
L0NDOS,
L0COMP,
L0NRSS, nextval('pmsi.s_rss'::regclass) AS rss_id,
base.date(L0AANP * 10000 + L0MMNP * 100 + L0JJNP) AS L0DTNP_date,
L0NOMP,
L0PREP,
L0SEXE,
SFGGHS,
CASE
WHEN L0GHM9 <> '' AND length(L0GHM9) = 6 THEN L0GHM9
WHEN SFGGHS IN ('1', '3') THEN '99Z99Z'
ELSE '' END
AS L0GHM9,
CASE
WHEN L0CCHI <> '' AND L0CCHI <> '0000' THEN L0CCHI
WHEN L0CSPE <> '' AND L0CSPE <> '0000' THEN L0CSPE
WHEN L0CME1 <> '' AND L0CME1 <> '0000' THEN L0CME1
ELSE L0CANE END AS L0CCHI,
CASE
WHEN L0GHM9 <> '' AND length(L0GHM9) = 6 AND L0GHM9 NOT LIKE '90%' AND L0FI14 = 'O' THEN 'V'
WHEN L0GHM9 <> '' AND length(L0GHM9) = 6 AND L0GHM9 NOT LIKE '90%' THEN 'G'
WHEN SFGGHS = '2' AND SFTYPA NOT IN ('01','05') THEN 'V'
ELSE 'S' END
AS L0ETAT,
CASE WHEN char_length(L0NGHS) > 0 THEN trim(leading '0' from L0NGHS) ELSE '0000' END AS L0NGHS,
L0FI14,
L0CMEN,
L0CPRO,
L0CMSO,
L0CDES,
L0CDP1,
L0CDP2,
L0PDBB,
case when ADDTE1 is not null THEN base.date(ADDTE1) ELSE base.date(L0AAEN * 10000 + L0MMEN * 100 + L0JJEN) END AS ADDTE1_date,
case when ADDOSS is not null THEN COALESCE(base.date(ADDTS1), GREATEST(base.date(ADDTE1), date(now()))) ELSE date(base.date(L0AASO * 10000 + L0MMSO * 100 + L0JJSO)) END AS ADDTS1_date,
'MF'::text AS origine_RSF,
0::integer as nb_seances,
L0CERR
FROM prod_shs.[PMSISCHEMA]_L0P01
LEFT JOIN pmsi.p_rss ON L0NRSS = p_rss.no_rss AND p_rss.etat = '' AND L0AASO = date_part('year', p_rss.date_sortie)
LEFT JOIN pmsi.p_rss p_rss_a ON L0NDOS = p_rss_a.no_sejour_administratif AND p_rss_a.etat = '' AND L0AASO = date_part('year', p_rss_a.date_sortie)
LEFT JOIN prod_shs.[ACTIVITESCHEMA]_ADP01 ON L0NDOS = ADDOSS AND ADDCPL = 0 AND ADCPRP = '1' AND base.date(ADDTS1) <= now()
LEFT JOIN prod_shs.[ACTIVITESCHEMA]_SFP01 ON ADCSER = SFCSER
WHERE L0AASO BETWEEN '[ANNEE]' AND date_part('year', now()) AND
L0NRSS > 0 AND
L0COMP = 0 AND
(
SFGGHS NOT IN ('','0','2') OR
SFGGHS = '2' AND SFTYPA <> '03' AND SFTYPA <> '04' AND ADCFAC = '1' OR
L0GHM9 <> '' AND length(L0GHM9) = 6
) AND
p_rss.no_rss IS NULL AND
p_rss_a.no_rss IS NULL
ORDER BY L0NRSS;
-- modifPL comptage des séances (compteur l0comp) pour séjours non facturés
DROP TABLE IF EXISTS w_rss_se;
CREATE TEMP TABLE w_rss_se AS
SELECT w_rss.L0NDOS, count(*) as compteur from prod_shs.[PMSISCHEMA]_L0P01
INNER JOIN w_rss on [PMSISCHEMA]_L0P01.L0NDOS = w_rss.L0NDOS
GROUP BY 1 HAVING count(*) > 1;
UPDATE w_rss SET
nb_seances = w_rss_se.compteur
FROM
w_rss_se
WHERE
w_rss_se.L0NDOS = w_rss.L0NDOS;
-- Supprime les doublons de no_rss sur les dossiers en cours (ils ne seront pas importés)
DROP TABLE IF EXISTS w_rss_doublons;
CREATE TEMP TABLE w_rss_doublons AS
SELECT L0NRSS FROM w_rss GROUP BY 1 HAVING count(*) > 1;
CTISELECT_PROPERTY_READ 'DOUBLONS_NORSS', COALESCE(base.cti_group_concat(L0NRSS),'')
FROM w_rss_doublons
;
warn numéros de RSS en doublon : {[DOUBLONS_NORSS]}. Ces dossiers ne seront pas importés ;
DELETE FROM w_rss WHERE L0NRSS = ANY(array(SELECT L0NRSS FROM w_rss GROUP BY 1 HAVING count(*) > 1)::bigint[]);
CREATE INDEX w_rss_i1 ON w_rss USING btree (rss_id);
CREATE INDEX w_rss_i2 ON w_rss USING btree (L0NDOS);
UPDATE w_rss
SET origine_RSF = 'JB'
FROM prod_shs.[PMSISCHEMA]_JBP05
WHERE JBNDOS = w_rss.L0NDOS AND JBCOMP = w_rss.L0COMP AND JBTTFA <> 0;
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.L0NRSS AS no_rss,
0 AS no_patient,
'' AS version_groupage,
date(L0DTNP_date) AS date_naissance,
L0SEXE AS sexe,
date(ADDTE1_date) AS date_entree,
date(ADDTS1_date) AS date_sortie,
L0CMEN AS mode_entree,
CASE WHEN L0CPRO = 0 OR char_length(L0CPRO) > 1 THEN ' ' ELSE L0CPRO::text END AS provenance,
L0CMSO AS mode_sortie,
CASE WHEN L0CDES = 0 OR char_length(L0CDES) > 1 THEN ' ' ELSE L0CDES::text END AS destination,
substr(trim(to_char(L0CDP1 * 1000 + L0CDP2,'FM0000000000')),6,5) AS code_postal,
L0PDBB AS poids_bebe,
0 AS igs2,
'' AS cma,
substr(L0GHM9 , 3 , 1) AS groupe_ghm,
CASE WHEN date(ADDTS1_date) > date(ADDTE1_date) THEN date(ADDTS1_date) - date(ADDTE1_date) ELSE 0 END AS duree_sejour,
CASE WHEN substr(L0GHM9,1,2) = '28' THEN 1 ELSE 1 END AS nb_rsa,
CASE WHEN date(ADDTE1_date) > date(L0DTNP_date) THEN trunc((date(ADDTE1_date) - date(L0DTNP_date)) / 365.25,0) ELSE 0 END AS age,
'' AS supprime,
now() AS date_import,
1 AS nb_rum,
'' AS secteur,
trim(to_char(L0NDOS,'00000000')) AS no_sejour_administratif,
w_rss.nb_seances AS nb_seances,
'' AS ghm_fg9,
COALESCE(t_ghm.oid, 0) AS ghm_id,
COALESCE(t_medecins.oid, 0) AS medecin_rss_id,
COALESCE(t_ghs.oid, 0) AS ghs_id,
date_part('year', ADDTS1_date) * 100 + date_part('month', ADDTS1_date) 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,
L0ETAT 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,
'' AS traitement_epmsi,
RIGHT(L0CERR,3) AS code_retour_groupage,
0 AS comite_medical_id,
'0' AS rehosp_meme_ghm,
0 AS from_oid
FROM w_rss
LEFT JOIN pmsi.t_ghm ON L0GHM9 = t_ghm.code
LEFT JOIN pmsi.t_ghs ON L0NGHS = t_ghs.code_text
LEFT JOIN pmsi.t_medecins ON L0CCHI = t_medecins.code;
-- transferts d'établissements
INSERT INTO base.t_etablissements(code, texte, texte_court)
SELECT
DDNDOP,
DDNDOP,
DDNDOP
FROM prod_shs.[ACTIVITESCHEMA]_DDP01
WHERE DDNDOP NOT IN (SELECT code FROM base.t_etablissements)
GROUP BY 1,2,3
;
/**********************************************************************************
* ETABLISSEMENT PROVENANCE ET DESTINATION (TRANSFERT) *
**********************************************************************************/
-- Insertion des établissement de provenance et destination dans p_rss_transfert
-- Traitement en commun réalisé dans import_rss_rsf_encours.php (generation_rum_post_traitements())
-- Grâce à la table w_TRANSFERTS
DROP TABLE IF EXISTS temp.w_TRANSFERTS;
CREATE TABLE temp.w_TRANSFERTS AS
SELECT
p_rss.oid AS rss_id,
import_id,
COALESCE((MAX(ARRAY[DDDCPL::text,provenance.oid::text]))[2],0::text)::bigint AS prov_id,
COALESCE((MAX(ARRAY[DDDCPL::text,destination.oid::text]))[2],0::text)::bigint AS dest_id
FROM
pmsi.p_rss
JOIN prod_shs.[ACTIVITESCHEMA]_DDP01 ON DDDOSS = no_sejour_administratif
LEFT JOIN base.t_etablissements provenance ON DDNDOP = provenance.code AND DDNDOP != ''
LEFT JOIN base.t_etablissements destination ON DDNDOD = destination.code AND DDNDOD != ''
WHERE 1=1 AND (
DDNDOD != '' OR
DDNDOP != '') AND
etat != 'S'
GROUP BY 1,2
;
]]></sqlcmd>
</NODE>
<NODE label="Identités">
<sqlcmd><![CDATA[
INSERT INTO pmsi.p_identites(
finess,
rss_id,
no_rss,
nom,
prenom,
nom_naissance)
SELECT
w_rss.finess AS finess,
w_rss.rss_id AS oid,
w_rss.L0NRSS AS no_rss,
L0NOMP AS nom,
L0PREP AS prenom,
'' AS nom_naissance
FROM w_rss;
UPDATE pmsi.p_rss
SET no_patient = L0DMED
FROM prod_shs.[PMSISCHEMA]_L0P01
WHERE p_rss.no_rss = L0NRSS AND
date_part('year', p_rss.date_sortie) = L0AASO AND
date_part('month', p_rss.date_sortie) = L0MMSO AND
no_patient IS DISTINCT FROM L0DMED;
UPDATE pmsi.p_rss
SET no_patient = ADDMED
FROM prod_shs.[ACTIVITESCHEMA]_adp01
WHERE no_sejour_administratif = ADDOSS AND
to_char(p_rss.date_sortie,'YYYYMMDD') = ADDTS1 AND
to_char(p_rss.date_naissance,'DDMMYYYY') = to_char(ADDTNM,'FM00000000') AND
no_patient <= 0;
]]></sqlcmd>
</NODE>
<NODE label="Rum">
<sqlcmd><![CDATA[
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 AS rss_id,
L0NRSS AS no_rss,
L2NRSC AS no_rum,
date(base.date(L2AENT * 10000 + L2MENT * 100 + L2JENT)) AS date_entree,
date(base.date(L2ASOR * 10000 + L2MSOR * 100 + L2JSOR)) AS date_sortie,
L2CMEN AS mode_entree,
CASE WHEN L2CPRO = 0 THEN ' ' ELSE L2CPRO::text END AS provenance,
L2CMSO AS mode_sortie,
CASE WHEN L2CDES = 0 THEN ' ' ELSE L2CDES::text END AS destination,
CASE WHEN date(base.date(L2ASOR * 10000 + L2MSOR * 100 + L2JSOR)) > date(base.date(L2AENT * 10000 + L2MENT * 100 + L2JENT)) THEN date(base.date(L2ASOR * 10000 + L2MSOR * 100 + L2JSOR)) - date(base.date(L2AENT * 10000 + L2MENT * 100 + L2JENT)) ELSE 0 END AS duree_sejour,
CASE WHEN w_rss.nb_seances > 0 THEN w_rss.nb_seances ELSE L2NBSE END AS nb_seances,
L2CDUM AS unite_medicale,
COALESCE(t_diagnostics.oid,0) AS diagnostic_principal_id,
COALESCE(t_diagnostics_relies.oid,0) AS diagnostic_relie_id,
COALESCE(t_unites_medicales.oid,0) AS unite_medicale_id,
'' AS type_autorisation,
L2NIGS AS igs2,
'' AS type_autorisation_lit_dedie,
'' AS supplement_code
FROM prod_shs.[PMSISCHEMA]_L2P01
JOIN w_rss ON (L2NDOS = w_rss.L0NDOS AND L2COMP = w_rss.L0COMP)
LEFT JOIN pmsi.t_unites_medicales ON (L2CDUM = t_unites_medicales.code)
LEFT JOIN pmsi.t_diagnostics ON (L2DIAG = t_diagnostics.code)
LEFT JOIN pmsi.t_diagnostics t_diagnostics_relies ON (L2DIAR = t_diagnostics_relies.code);
DROP TABLE IF EXISTS w_rss_rum;
CREATE TEMP TABLE w_rss_rum AS
SELECT p_rss_rum.rss_id,
count(*) AS nb_rum,
SUM(p_rss_rum.nb_seances) AS nb_seances,
MIN(no_rum) AS no_premier_rum
FROM pmsi.p_rss_rum, pmsi.p_rss
WHERE p_rss.oid = p_rss_rum.rss_id AND en_cours = '1'
GROUP BY 1;
UPDATE pmsi.p_rss
SET
nb_rum = w_rss_rum.nb_rum,
no_rum_principal = p_rss_rum.no_rum,
unite_medicale_principale_id = p_rss_rum.unite_medicale_id,
nb_seances = w_rss_rum.nb_seances
FROM w_rss_rum, pmsi.p_rss_rum
WHERE p_rss.oid = w_rss_rum.rss_id AND 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;
]]></sqlcmd>
</NODE>
<NODE label="Diagnostics">
<sqlcmd><![CDATA[
INSERT INTO pmsi.p_rss_diagnostics(
finess,
rss_id,
no_rss,
no_rum,
diagnostic_id,
type_diagnostic,
type_diagnostic_rss,
imprecis,
unite_medicale,
unite_medicale_id)
SELECT
w_rss.finess,
w_rss.rss_id,
w_rss.L0NRSS,
L5NRSC AS no_rum,
COALESCE(t_diagnostics.oid,0) AS diagnostic_id,
CASE
WHEN L5PRIN = '1' THEN 'DP'
WHEN L5PRIN = '2' THEN 'DR'
WHEN L5PRIN = '3' THEN 'DD'
ELSE 'DA' END::text AS type_diagnostic,
CASE
WHEN L5PRIN = '1' THEN 'DP'
WHEN L5PRIN = '2' THEN 'DR'
WHEN L5PRIN = '3' THEN 'DD'
ELSE 'DA' END::text AS type_diagnostic_rss,
'' AS imprecis,
L2CDUM AS unite_medicale,
COALESCE(t_unites_medicales.oid,0) AS unite_medicale_id
FROM prod_shs.[PMSISCHEMA]_L5P01
JOIN prod_shs.[PMSISCHEMA]_L2P01 ON (L2NDOS = L5NDOS AND L2COMP = L5COMP AND L2NRSC = L5NRSC)
JOIN w_rss ON (L2NDOS = w_rss.L0NDOS AND L2COMP = w_rss.L0COMP)
JOIN pmsi.t_diagnostics ON (L5CDAD = t_diagnostics.code)
LEFT JOIN pmsi.t_unites_medicales ON (L2CDUM = t_unites_medicales.code)
WHERE L5CNOM = 'CIM10' AND L5PRIN IN ('', '1', '2');
]]></sqlcmd>
</NODE>
<NODE label="Actes">
<sqlcmd><![CDATA[
-- Le champ "rang" permet d'ordonner les actes quand il y a plusieurs occurences d'actes avec les éléments suivants identiques :
-- no dossier, code acte, date acte, medecin exécutant, phase CCAM, extension CCAM
DROP TABLE IF EXISTS w_rss_actes;
CREATE TEMP TABLE w_rss_actes AS
SELECT
w_rss.finess,
w_rss.rss_id,
w_rss.L0NDOS AS no_dossier,
w_rss.L0NRSS AS no_rss,
L5NRSC AS no_rum,
L2CDUM AS unite_medicale,
COALESCE(t_unites_medicales.oid,0) AS unite_medicale_id,
date(base.date(L5ANNE * 10000 + L5MOIS * 100 + L5JOUR)) AS date_acte,
COALESCE(t_medecins.oid,0) AS medecin_id,
COALESCE(t_actes.oid,0) AS acte_id,
1 AS nombre,
L5FI13 AS phase_ccam,
L5FI12 AS activite_ccam,
''::text AS extension_ccam,
''::text AS modificateur_ccam_1,
''::text AS modificateur_ccam_2,
''::text AS modificateur_ccam_3,
''::text AS modificateur_ccam_4,
''::text AS remboursement_excp_ccam,
''::text AS association_nonprevue_ccam,
rank() OVER (PARTITION BY
w_rss.L0NDOS,
COALESCE(t_actes.oid,0),
date(base.date(L5ANNE * 10000 + L5MOIS * 100 + L5JOUR)),
COALESCE(t_medecins.oid,0),
L5FI13,
L5FI12 ORDER BY L5NLIG
) as rang
FROM prod_shs.[PMSISCHEMA]_L5P01
JOIN prod_shs.[PMSISCHEMA]_L2P01 ON L2NDOS = L5NDOS AND L2COMP = L5COMP AND L2NRSC = L5NRSC
JOIN w_rss ON L2NDOS = w_rss.L0NDOS AND L2COMP = w_rss.L0COMP
JOIN pmsi.t_actes ON substring(L5CDAD, 1, 7) = t_actes.code
LEFT JOIN pmsi.t_medecins ON L5CMED = t_medecins.code
LEFT JOIN pmsi.t_unites_medicales ON L2CDUM = t_unites_medicales.code
WHERE L5CNOM = 'CCAM';
-- Mise à jour de w_rss_actes depuis MFP01CCAM pour récupérer les modificateurs CCAM et le code association non prévue
-- La "jointure" se fait pour les actes qui ont les éléments suivants identiques :
-- no dossier, code acte, date acte, medecin exécutant, phase CCAM, extension CCAM, rang de classement
WITH w_actes_infos AS (
SELECT
MFDOSS as no_dossier,
COALESCE(t_actes.oid,0) AS acte_id,
base.date(MFDTA1) as date_acte,
COALESCE(t_medecins.oid,0) AS medecin_id,
MFCCPT as phase_ccam,
MFCCAC AS activite_ccam,
MFCCXD AS extension_ccam,
MFCCM1 AS modificateur_ccam_1,
MFCCM2 AS modificateur_ccam_2,
MFCCM3 AS modificateur_ccam_3,
MFCCM4 AS modificateur_ccam_4,
MFCCAP AS association_nonprevue_ccam,
rank() OVER (PARTITION BY
MFDOSS,
COALESCE(t_actes.oid,0),
date(base.date(MFDTA1)),
COALESCE(t_medecins.oid,0),
MFCCPT,
MFCCAC ORDER BY MFACNU
) as rang
FROM
prod_shs.[ACTIVITESCHEMA]_MFP01CCAM
JOIN pmsi.t_actes ON substring(MFCCAM, 1, 7) = t_actes.code
JOIN pmsi.t_medecins on to_char(MFRUPR,'FM0000') = t_medecins.code
JOIN w_rss ON w_rss.L0NDOS = MFDOSS
WHERE
MFDCPL = 0
)
UPDATE w_rss_actes SET
extension_ccam = w_actes_infos.extension_ccam,
modificateur_ccam_1 = w_actes_infos.modificateur_ccam_1,
modificateur_ccam_2 = w_actes_infos.modificateur_ccam_2,
modificateur_ccam_3 = w_actes_infos.modificateur_ccam_3,
modificateur_ccam_4 = w_actes_infos.modificateur_ccam_4,
association_nonprevue_ccam = w_actes_infos.association_nonprevue_ccam
FROM
w_actes_infos
WHERE 1=1
AND w_actes_infos.no_dossier = w_rss_actes.no_dossier
AND w_actes_infos.acte_id = w_rss_actes.acte_id
AND w_actes_infos.date_acte = w_rss_actes.date_acte
AND w_actes_infos.medecin_id = w_rss_actes.medecin_id
AND w_actes_infos.phase_ccam = w_rss_actes.phase_ccam
AND w_actes_infos.activite_ccam = w_rss_actes.activite_ccam
AND w_actes_infos.rang = w_rss_actes.rang;
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
)
SELECT
w_rss_actes.finess,
w_rss_actes.rss_id,
w_rss_actes.no_rss,
w_rss_actes.no_rum,
w_rss_actes.unite_medicale,
w_rss_actes.unite_medicale_id,
w_rss_actes.date_acte,
w_rss_actes.medecin_id,
w_rss_actes.acte_id,
w_rss_actes.nombre,
w_rss_actes.phase_ccam,
w_rss_actes.activite_ccam,
w_rss_actes.extension_ccam,
w_rss_actes.modificateur_ccam_1,
w_rss_actes.modificateur_ccam_2,
w_rss_actes.modificateur_ccam_3,
w_rss_actes.modificateur_ccam_4,
w_rss_actes.remboursement_excp_ccam,
w_rss_actes.association_nonprevue_ccam
FROM
w_rss_actes;
-- Actes externes absents du PMSI
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
)
SELECT
w_rss.finess,
w_rss.rss_id,
w_rss.L0NRSS AS no_rss,
1 AS no_rum,
p_rss_rum.unite_medicale,
p_rss_rum.unite_medicale_id,
w_rss.ADDTE1_date AS date_acte,
COALESCE(t_medecins.oid,0) AS medecin_id,
COALESCE(t_actes.oid,0) AS acte_id,
MFNBRE AS nombre,
MFCCPT AS phase_ccam,
MFCCAC AS activite_ccam,
MFCCXD AS extension_ccam,
MFCCM1 AS modificateur_ccam_1,
MFCCM2 AS modificateur_ccam_2,
MFCCM3 AS modificateur_ccam_3,
MFCCM4 AS modificateur_ccam_4,
'' AS remboursement_excp_ccam,
MFCCAP AS association_nonprevue_ccam
FROM prod_shs.[ACTIVITESCHEMA]_MFP01CCAM
JOIN w_rss ON MFDOSS = w_rss.L0NDOS AND MFDCPL = 0
JOIN pmsi.p_rss_rum ON w_rss.rss_id = p_rss_rum.rss_id AND no_rum = 1
JOIN pmsi.t_actes ON substring(MFCCAM, 1, 7) = t_actes.code
LEFT JOIN pmsi.t_medecins ON to_char(MFRUPR,'FM0000') = t_medecins.code
LEFT JOIN pmsi.p_rss_actes ON w_rss.rss_id = p_rss_actes.rss_id AND t_actes.oid = p_rss_actes.acte_id
WHERE w_rss.SFGGHS = '2' AND p_rss_actes.rss_id IS NULL ;
]]></sqlcmd>
</NODE>
<NODE label="Factures">
<sqlcmd><![CDATA[
-- C.A. depuis RSF
INSERT INTO pmsi.p_rsf_total(
finess,
rss_id,
no_rss,
code_pec,
rang_beneficiaire,
regime,
nature_pec,
justificatif_exo,
no_facture,
code_regularisation,
matricule_assure,
cle_matricule_assure,
base_remboursement,
sejour_facture,
sejour_remboursable,
honoraires_factures,
honoraires_remboursable,
t2a_facture,
dmi_facture,
phc_facture,
participation_assure_avant_oc,
sejour_remboursable_2,
honoraires_remboursable_2,
montant_dmi_ghs2006,
nb_si,
ca_si,
nb_sur,
ca_sur,
nb_rea,
ca_rea,
nb_neonat,
ca_neonat,
nb_exh,
ca_exh,
nb_exb,
ca_exb,
nb_ghs,
ca_ghs,
ca_ghs_theorique,
taux_remboursement)
SELECT
w_rss.finess AS finess,
w_rss.rss_id AS rss_id,
w_rss.L0NRSS AS no_rss,
MAX(JBCPEC) AS code_pec,
MAX(JBRBEN) AS rang_beneficiaire,
MAX(JBRGP2) AS regime,
MAX(JBRIPC) AS nature_pec,
MAX(JBJETM) AS justificatif_exo,
MAX(JBNFAC) AS no_facture,
MAX(JBNOPE) AS code_regularisation,
'' AS matricule_assure,
'' AS cle_matricule_assure,
SUM(JBTTFA) AS base_remboursement,
SUM(JBTTFA) AS sejour_facture,
SUM(JBTTFA) AS sejour_remboursable,
SUM(JBTTFH) AS honoraires_factures,
SUM(JBTRCH) AS honoraires_remboursable,
0 AS t2a_facture,
0 AS dmi_facture,
0 AS phc_facture,
SUM(JBMPTA) AS participation_assure_avant_oc,
0 AS sejour_remboursable_2,
0 AS honoraires_remboursable_2,
0 AS montant_dmi_ghs2006,
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,
0 AS nb_exh,
0 AS ca_exh,
0 AS nb_exb,
0 AS ca_exb,
0 AS nb_ghs,
0 AS ca_ghs,
0 AS ca_ghs_theorique,
0 AS taux_remboursement
FROM prod_shs.[PMSISCHEMA]_JBP05
JOIN w_rss ON JBNDOS = w_rss.L0NDOS AND JBCOMP = w_rss.L0COMP AND origine_RSF = 'JB'
GROUP BY 1,2,3;
-- C.A. depuis facturation si pas dans RSF
INSERT INTO pmsi.p_rsf_total(
finess,
rss_id,
no_rss,
code_pec,
rang_beneficiaire,
regime,
nature_pec,
justificatif_exo,
no_facture,
code_regularisation,
matricule_assure,
cle_matricule_assure,
base_remboursement,
sejour_facture,
sejour_remboursable,
honoraires_factures,
honoraires_remboursable,
t2a_facture,
dmi_facture,
phc_facture,
participation_assure_avant_oc,
sejour_remboursable_2,
honoraires_remboursable_2,
montant_dmi_ghs2006,
nb_si,
ca_si,
nb_sur,
ca_sur,
nb_rea,
ca_rea,
nb_neonat,
ca_neonat,
nb_exh,
ca_exh,
nb_exb,
ca_exb,
nb_ghs,
ca_ghs,
ca_ghs_theorique,
taux_remboursement)
SELECT
w_rss.finess AS finess,
w_rss.rss_id AS rss_id,
w_rss.L0NRSS AS no_rss,
'' AS code_pec,
'' AS rang_beneficiaire,
'' AS regime,
'' AS nature_pec,
'' AS justificatif_exo,
MAX(to_char(MFDOSS,'FM00000000')) AS no_facture,
'1' AS code_regularisation,
'' AS matricule_assure,
'' AS cle_matricule_assure,
SUM(MFMTFA) AS base_remboursement,
SUM(MFMTFA) AS sejour_facture,
SUM(MFMFA1) AS sejour_remboursable,
0 AS honoraires_factures,
0 AS honoraires_remboursable,
0 AS t2a_facture,
0 AS dmi_facture,
0 AS phc_facture,
SUM(MFMFAM) AS participation_assure_avant_oc,
0 AS sejour_remboursable_2,
0 AS honoraires_remboursable_2,
0 AS montant_dmi_ghs2006,
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,
0 AS nb_exh,
0 AS ca_exh,
0 AS nb_exb,
0 AS ca_exb,
0 AS nb_ghs,
0 AS ca_ghs,
0 AS ca_ghs_theorique,
0 AS taux_remboursement
FROM prod_shs.[ACTIVITESCHEMA]_MFP01CLI
JOIN w_rss ON MFDOSS = w_rss.L0NDOS AND MFDCPL = 0 AND origine_RSF = 'MF'
JOIN prod_shs.[ACTIVITESCHEMA]_TRP01 ON TRCENR = 'A51' AND
TRCSER = MFCSER AND TRCRUB = substr(to_char(MFRUPR,'FM0000'),2,3)
JOIN pmsi.t_prestations ON CASE WHEN MFRUPR IN (111,112) THEN 'GHS' ELSE TRPRSA END = t_prestations.code
LEFT JOIN pmsi.p_rsf_total ON w_rss.rss_id = p_rsf_total.rss_id
WHERE p_rsf_total.rss_id IS NULL AND
(MFMFA1 <> 0 OR t_prestations.code IN ('GHS', 'EXH', 'ATU', 'FFM', 'SE1', 'SE2', 'SE3', 'SE4', 'SE5', 'SE6', 'SE7', 'APE', 'AP2', 'FPI', 'FFM'))
GROUP BY 1,2,3;
INSERT INTO pmsi.p_rsf_total(
finess, no_rss, code_pec, rang_beneficiaire, regime, nature_pec,
justificatif_exo, no_facture, code_regularisation, base_remboursement,
sejour_facture, sejour_remboursable, honoraires_factures, honoraires_remboursable,
t2a_facture, dmi_facture, phc_facture, participation_assure_avant_oc,
sejour_remboursable_2, honoraires_remboursable_2, montant_dmi_ghs2006,
nb_si, ca_si, nb_sur, ca_sur, nb_rea, ca_rea, nb_neonat, ca_neonat,
nb_exh, ca_exh, nb_exb, ca_exb, nb_ghs, ca_ghs, rss_id, ca_ghs_theorique)
SELECT
p_rss.finess, p_rss.no_rss, '', '', '', '', '', '', '', 0, 0, 0, 0, 0, 0, 0, 0, 0,
0, 0, 0, 0, 0, 0, 0, 0, 0, 0, 0, 0, 0, 0, 0, 0, 0, p_rss.oid, 0
FROM pmsi.p_rss LEFT JOIN pmsi.p_rsf_total ON (p_rsf_total.rss_id = p_rss.oid)
WHERE en_cours = '1' AND p_rsf_total.rss_id IS NULL;
]]></sqlcmd>
</NODE>
<NODE label="Prestations">
<sqlcmd><![CDATA[
-- Detail RSF depuis PMSI
INSERT INTO pmsi.p_rsf_detail(
finess,
rss_id,
no_rss,
nature,
mt,
dmt,
date_debut,
date_fin,
nombre,
coefficient,
prix_unitaire,
base_remboursement,
taux_remboursement,
sejour_facture,
sejour_remboursable,
compteur,
ligne_t2a,
pec_fj,
coefficient_mco,
sejour_remboursable_2,
ghs_id,
sejour_rembourse_noemie,
nature_noemie,
prestation_id,
type,
coefficient_geo,
est_ligne_rss,
est_ligne_rum,
no_rum,
unite_medicale_id,
base_remboursement_rum)
SELECT
w_rss.finess AS finess,
w_rss.rss_id AS rss_id,
w_rss.L0NRSS AS no_rss,
'' AS nature,
'' AS mt,
'' AS dmt,
date(base.date(JBSSDS * 1000000 + JBAADS * 10000 + JBMMDS * 100 + JBJJDS)) AS date_debut,
date(base.date(JBSSFS * 1000000 + JBAAFS * 10000 + JBMMFS * 100 + JBJJFS)) AS date_fin,
JBQACT AS nombre,
JBCOEG AS coefficient,
JBPUNI AS prix_unitaire,
JBMTFA AS base_remboursement,
JBTPAM AS taux_remboursement,
JBMTFA AS sejour_facture,
JBMTFA AS sejour_remboursable,
0 AS compteur,
'' AS ligne_t2a,
'' AS pec_fj,
JBCMCO AS coefficient_mco,
0 AS sejour_remboursable_2,
COALESCE(t_ghs.oid, 0) AS ghs_id,
0 AS sejour_rembourse_noemie,
'' AS nature_noemie,
COALESCE(t_prestations.oid, 0) AS prestation_id,
'B' AS type,
0 AS coefficient_geo,
'1' AS est_ligne_rss,
'0' AS est_ligne_rum,
1 AS no_rum,
0 AS unite_medicale_id,
0 AS base_remboursement_rum
FROM prod_shs.[PMSISCHEMA]_JBP01
JOIN w_rss ON JBNDOS = w_rss.L0NDOS AND JBCOMP = w_rss.L0COMP AND origine_RSF = 'JB'
JOIN pmsi.t_prestations ON JBCACT = t_prestations.code
LEFT JOIN pmsi.t_ghs ON to_number(CASE WHEN JBNGHS BETWEEN '0000' AND '9999' THEN JBNGHS ELSE '9999' END,'0000') = t_ghs.code;
-- Detail RSF depuis Facturation (externes ou pas de RSF dans PMSI)
-- Sauf GHS
INSERT INTO pmsi.p_rsf_detail(
finess,
rss_id,
no_rss,
nature,
mt,
dmt,
date_debut,
date_fin,
nombre,
coefficient,
prix_unitaire,
base_remboursement,
taux_remboursement,
sejour_facture,
sejour_remboursable,
compteur,
ligne_t2a,
pec_fj,
coefficient_mco,
sejour_remboursable_2,
ghs_id,
sejour_rembourse_noemie,
nature_noemie,
prestation_id,
type,
coefficient_geo,
est_ligne_rss,
est_ligne_rum,
no_rum,
unite_medicale_id,
base_remboursement_rum)
SELECT
w_rss.finess AS finess,
w_rss.rss_id AS rss_id,
w_rss.L0NRSS AS no_rss,
'' AS nature,
'' AS mt,
'' AS dmt,
ADDTE1_date AS date_debut,
ADDTS1_date AS date_fin,
MFNBRE AS nombre,
1 AS coefficient,
MFPRUA AS prix_unitaire,
MFMTFA AS base_remboursement,
MFTFA1 AS taux_remboursement,
MFMTFA AS sejour_facture,
MFMFA1 AS sejour_remboursable,
0 AS compteur,
'' AS ligne_t2a,
'' AS pec_fj,
1 AS coefficient_mco,
0 AS sejour_remboursable_2,
COALESCE(t_ghs.oid, 0) AS ghs_id,
0 AS sejour_rembourse_noemie,
'' AS nature_noemie,
COALESCE(t_prestations.oid, 0) AS prestation_id,
'B' AS type,
0 AS coefficient_geo,
'1' AS est_ligne_rss,
'0' AS est_ligne_rum,
1 AS no_rum,
0 AS unite_medicale_id,
0 AS base_remboursement_rum
FROM prod_shs.[ACTIVITESCHEMA]_MFP01CLI
JOIN w_rss ON MFDOSS = w_rss.L0NDOS AND MFDCPL = 0 AND origine_RSF = 'MF'
JOIN prod_shs.[ACTIVITESCHEMA]_TRP01 ON TRCENR = 'A51' AND
TRCSER = MFCSER AND TRCRUB = substr(to_char(MFRUPR,'FM0000'),2,3)
JOIN pmsi.t_prestations ON CASE WHEN MFRUPR IN (111,112) THEN 'GHS' WHEN TRPRST <> '' THEN TRPRST ELSE TRPRSA END = t_prestations.code
LEFT JOIN pmsi.t_ghs ON to_number(CASE WHEN MFCGHS BETWEEN '0000' AND '9999' THEN MFCGHS ELSE '9999' END,'0000') = t_ghs.code
WHERE (MFMFA1 <> 0 AND t_prestations.code NOT IN ('GHS') OR
t_prestations.code IN ('EXH', 'ATU', 'FFM', 'SE1', 'SE2', 'SE3', 'SE4' ,'SE5', 'SE6', 'SE7', 'APE', 'AP2', 'FPI', 'FFM') OR
t_prestations.code IN ('GHS') AND MFCGHS = 9605
);
-- Detail RSF depuis Facturation (externes ou pas de RSF dans PMSI)
-- CAS Spécial du GHS
INSERT INTO pmsi.p_rsf_detail(
finess,
rss_id,
no_rss,
nature,
mt,
dmt,
date_debut,
date_fin,
nombre,
coefficient,
prix_unitaire,
base_remboursement,
taux_remboursement,
sejour_facture,
sejour_remboursable,
compteur,
ligne_t2a,
pec_fj,
coefficient_mco,
sejour_remboursable_2,
ghs_id,
sejour_rembourse_noemie,
nature_noemie,
prestation_id,
type,
coefficient_geo,
est_ligne_rss,
est_ligne_rum,
no_rum,
unite_medicale_id,
base_remboursement_rum)
SELECT
w_rss.finess AS finess,
w_rss.rss_id AS rss_id,
w_rss.L0NRSS AS no_rss,
'' AS nature,
'' AS mt,
'' AS dmt,
ADDTE1_date AS date_debut,
ADDTS1_date AS date_fin,
1 AS nombre,
1 AS coefficient,
MAX(MFPRUA) AS prix_unitaire,
SUM(MFMTFA) AS base_remboursement,
MAX(MFTFA1) AS taux_remboursement,
SUM(MFMTFA) AS sejour_facture,
SUM(MFMFA1) AS sejour_remboursable,
0 AS compteur,
'' AS ligne_t2a,
'' AS pec_fj,
1 AS coefficient_mco,
0 AS sejour_remboursable_2,
COALESCE(t_ghs.oid, 0) AS ghs_id,
0 AS sejour_rembourse_noemie,
'' AS nature_noemie,
COALESCE(t_prestations.oid, 0) AS prestation_id,
'B' AS type,
0 AS coefficient_geo,
'1' AS est_ligne_rss,
'0' AS est_ligne_rum,
1 AS no_rum,
0 AS unite_medicale_id,
0 AS base_remboursement_rum
FROM prod_shs.[ACTIVITESCHEMA]_MFP01CLI
JOIN w_rss ON MFDOSS = w_rss.L0NDOS AND MFDCPL = 0 AND origine_RSF = 'MF'
JOIN prod_shs.[ACTIVITESCHEMA]_TRP01 ON TRCENR = 'A51' AND
TRCSER = MFCSER AND TRCRUB = substr(to_char(MFRUPR,'FM0000'),2,3)
JOIN pmsi.t_prestations ON CASE WHEN MFRUPR IN (111,112) THEN 'GHS' WHEN TRPRST <> '' THEN TRPRST ELSE TRPRSA END = t_prestations.code
LEFT JOIN pmsi.t_ghs ON to_number(CASE WHEN MFCGHS BETWEEN '0000' AND '9999' THEN MFCGHS ELSE '9999' END,'0000') = t_ghs.code
WHERE t_prestations.code IN ('GHS') AND MFCGHS <> 9605
GROUP BY 1,2,3,7,8,21,24;
]]></sqlcmd>
</NODE>
<NODE label="LPP">
<sqlcmd><![CDATA[
INSERT INTO pmsi.p_rss_lpp(
finess,
rss_id,
no_rss,
rang,
date_lpp,
lpp_id,
nombre,
prix_unitaire,
montant_facture,
non_pris_en_compte)
SELECT
w_rss.finess AS finess,
w_rss.rss_id AS rss_id,
w_rss.L0NRSS AS no_rss,
'' AS rang,
date(base.date(JBSPDS * 1000000 + JBAPDS * 10000 + JBMPDS * 100 + JBJPDS)) AS date_lpp,
COALESCE(t_lpp.oid, 0) AS lpp_id,
JBQTE1 AS nombre,
JBPRU1 AS prix_unitaire,
JBMTF1 AS montant_facture,
'0' AS non_pris_en_compte
FROM prod_shs.[PMSISCHEMA]_JBP03
JOIN w_rss ON JBNDOS = w_rss.L0NDOS AND JBCOMP = w_rss.L0COMP
JOIN pmsi.t_lpp ON (JBLPP1 = t_lpp.code);
]]></sqlcmd>
</NODE>
<NODE label="Finalisation">
<sqlcmd><![CDATA[
-- Suppression externes non SE, FFM, ATU)
DELETE FROM pmsi.p_rss
WHERE ghm_id = 0 AND
en_cours = '1' AND
p_rss.oid NOT IN (
SELECT rss_id
FROM pmsi.p_rsf_detail
JOIN pmsi.t_prestations ON prestation_id = t_prestations.oid
WHERE t_prestations.code IN ('SE1', 'SE2', 'SE3', 'SE4', 'SE5', 'SE6', 'SE7', 'APE', 'AP2', 'FPI', 'FFM', 'ATU')
);
DELETE FROM pmsi.p_rss_rum
WHERE rss_id NOT IN (SELECT oid FROM pmsi.p_rss);
DELETE FROM pmsi.p_rss_actes
WHERE rss_id NOT IN (SELECT oid FROM pmsi.p_rss);
DELETE FROM pmsi.p_rss_diagnostics
WHERE rss_id NOT IN (SELECT oid FROM pmsi.p_rss);
DELETE FROM pmsi.p_rss_lpp
WHERE rss_id NOT IN (SELECT oid FROM pmsi.p_rss);
DELETE FROM pmsi.p_rss_ucd
WHERE rss_id NOT IN (SELECT oid FROM pmsi.p_rss);
DELETE FROM pmsi.p_rss_etat
WHERE rss_id NOT IN (SELECT oid FROM pmsi.p_rss);
DELETE FROM pmsi.p_rsf_total
WHERE rss_id NOT IN (SELECT oid FROM pmsi.p_rss);
DELETE FROM pmsi.p_rsf_detail
WHERE rss_id NOT IN (SELECT oid FROM pmsi.p_rss);
DELETE FROM pmsi.p_identites
WHERE rss_id NOT IN (SELECT oid FROM pmsi.p_rss);
]]></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[
DROP TABLE IF EXISTS w_L0P01;
CREATE TEMP TABLE w_L0P01 AS
SELECT L0NRSS,
L0AASO,
MAX(L0DTGR) AS L0DTGR_original,
to_date(MAX(to_char(L0DTGR,'FM00000000')),'YYYYMMDD') AS L0DTGR
FROM prod_shs.[PMSISCHEMA]_L0P01
WHERE L0NRSS > 0 AND L0NDME > 0
GROUP BY 1,2;
ALTER TABLE w_L0P01 ADD CONSTRAINT w_L0P01_pkey PRIMARY KEY(L0NRSS);
UPDATE pmsi.p_rss_etat
SET date_groupage = CASE WHEN L0DTGR >= date_sortie THEN L0DTGR ELSE '20991231' END
FROM pmsi.p_rss
JOIN w_L0P01 ON L0NRSS = no_rss AND date_part('year',date_sortie) = L0AASO
WHERE p_rss_etat.rss_id = p_rss.oid AND
date_groupage IS DISTINCT FROM CASE WHEN L0DTGR >= date_sortie THEN L0DTGR ELSE '20991231' END;
DROP TABLE IF EXISTS w_L0P01;
CREATE TEMP TABLE w_L0P01 AS
SELECT to_char(L0NDOS,'FM00000000') AS L0NDOS,
MAX(L0DTGR) AS L0DTGR_original,
to_date(MAX(to_char(L0DTGR,'FM00000000')),'YYYYMMDD') AS L0DTGR
FROM prod_shs.[PMSISCHEMA]_L0P01
GROUP BY 1;
ALTER TABLE w_L0P01 ADD CONSTRAINT w_L0P01_pkey PRIMARY KEY(L0NDOS);
UPDATE pmsi.p_rss_etat
SET date_groupage = CASE WHEN L0DTGR >= date_sortie THEN L0DTGR ELSE '20991231' END
FROM pmsi.p_rss
JOIN w_L0P01 ON L0NDOS = no_sejour_administratif
WHERE p_rss_etat.rss_id = p_rss.oid AND
date_groupage IS DISTINCT FROM CASE WHEN L0DTGR >= date_sortie THEN L0DTGR ELSE '20991231' END AND
L0DTGR >= date_sortie;
DROP TABLE IF EXISTS w_ADP01;
CREATE TEMP TABLE w_ADP01 AS
SELECT to_char(ADDOSS,'FM00000000') AS ADDOSS,
CASE WHEN ADDOSS >= 10000000 THEN to_char(ADDOSS,'FM00000000') ELSE to_char(ADDOSS,'FM0000000') END AS ADDOSS2,
MAX(to_date(
CASE
WHEN ADCFAC = '1' AND ADDTFA <> 0 THEN to_char(ADDTFA,'FM00000000')
WHEN ADCFAC = '1' AND ADDTFA = 0 THEN to_char(now(),'YYYYMMDD')
ELSE '20991231' END,'YYYYMMDD')) AS ADDTFA
FROM prod_shs.[ACTIVITESCHEMA]h_ADP01H
WHERE ADADAV IN ('0','3')
GROUP BY 1,2;
ALTER TABLE w_ADP01 ADD CONSTRAINT w_ADP01_pkey PRIMARY KEY(ADDOSS);
UPDATE pmsi.p_rss_etat
SET date_facture = CASE WHEN ADDTFA >= date_sortie AND ADDTFA <> '20991231' THEN ADDTFA ELSE '20991231' END,
est_facture = CASE WHEN ADDTFA >= date_sortie AND ADDTFA <> '20991231' THEN '1' ELSE '0' END
FROM pmsi.p_rss
JOIN w_ADP01 ON ADDOSS = no_sejour_administratif
WHERE p_rss_etat.rss_id = p_rss.oid AND
(
date_facture IS DISTINCT FROM CASE WHEN ADDTFA >= date_sortie AND ADDTFA <> '20991231' THEN ADDTFA ELSE '20991231' END
OR
est_facture IS DISTINCT FROM CASE WHEN ADDTFA >= date_sortie AND ADDTFA <> '20991231' THEN '1' ELSE '0' END
);
UPDATE pmsi.p_rss_etat
SET date_facture = CASE WHEN ADDTFA >= date_sortie AND ADDTFA <> '20991231' THEN ADDTFA ELSE '20991231' END,
est_facture = CASE WHEN ADDTFA >= date_sortie AND ADDTFA <> '20991231' THEN '1' ELSE '0' END
FROM pmsi.p_rss
JOIN w_ADP01 ON ADDOSS2 = no_sejour_administratif
WHERE p_rss_etat.rss_id = p_rss.oid AND
(
date_facture IS DISTINCT FROM CASE WHEN ADDTFA >= date_sortie AND ADDTFA <> '20991231' THEN ADDTFA ELSE '20991231' END
OR
est_facture IS DISTINCT FROM CASE WHEN ADDTFA >= date_sortie AND ADDTFA <> '20991231' THEN '1' ELSE '0' END
);
DROP TABLE IF EXISTS w_ADP01;
CREATE TEMP TABLE w_ADP01 AS
SELECT to_char(ADDOSS,'FM00000000') AS ADDOSS,
CASE WHEN ADDOSS >= 10000000 THEN to_char(ADDOSS,'FM00000000') ELSE to_char(ADDOSS,'FM0000000') END AS ADDOSS2,
MAX(to_date(
CASE
WHEN ADCFAC = '1' AND ADDTFA <> 0 THEN to_char(ADDTFA,'FM00000000')
WHEN ADCFAC = '1' AND ADDTFA = 0 THEN to_char(now(),'YYYYMMDD')
ELSE '20991231' END,'YYYYMMDD')) AS ADDTFA
FROM prod_shs.[ACTIVITESCHEMA]p_ADP01P
WHERE ADADAV IN ('0','3')
GROUP BY 1,2;
ALTER TABLE w_ADP01 ADD CONSTRAINT w_ADP01_pkey PRIMARY KEY(ADDOSS);
UPDATE pmsi.p_rss_etat
SET date_facture = CASE WHEN ADDTFA >= date_sortie THEN ADDTFA ELSE '20991231' END,
est_facture = CASE WHEN ADDTFA >= date_sortie THEN '1' ELSE '0' END
FROM pmsi.p_rss
JOIN w_ADP01 ON ADDOSS = no_sejour_administratif
WHERE p_rss_etat.rss_id = p_rss.oid AND
(
date_facture IS DISTINCT FROM CASE WHEN ADDTFA >= date_sortie AND ADDTFA <> '20991231' THEN ADDTFA ELSE '20991231' END
OR
est_facture IS DISTINCT FROM CASE WHEN ADDTFA >= date_sortie AND ADDTFA <> '20991231' THEN '1' ELSE '0' END
);
UPDATE pmsi.p_rss_etat
SET date_facture = CASE WHEN ADDTFA >= date_sortie THEN ADDTFA ELSE '20991231' END,
est_facture = CASE WHEN ADDTFA >= date_sortie THEN '1' ELSE '0' END
FROM pmsi.p_rss
JOIN w_ADP01 ON ADDOSS2 = no_sejour_administratif
WHERE p_rss_etat.rss_id = p_rss.oid AND
(
date_facture IS DISTINCT FROM CASE WHEN ADDTFA >= date_sortie AND ADDTFA <> '20991231' THEN ADDTFA ELSE '20991231' END
OR
est_facture IS DISTINCT FROM CASE WHEN ADDTFA >= date_sortie AND ADDTFA <> '20991231' THEN '1' ELSE '0' END
);
DROP TABLE IF EXISTS w_ADP01;
CREATE TEMP TABLE w_ADP01 AS
SELECT to_char(ADDOSS,'FM00000000') AS ADDOSS,
CASE WHEN ADDOSS >= 10000000 THEN to_char(ADDOSS,'FM00000000') ELSE to_char(ADDOSS,'FM0000000') END AS ADDOSS2,
MAX(to_date(
CASE
WHEN ADCFAC = '1' AND ADDTFA <> 0 THEN to_char(ADDTFA,'FM00000000')
WHEN ADCFAC = '1' AND ADDTFA = 0 THEN to_char(now(),'YYYYMMDD')
ELSE '20991231' END,'YYYYMMDD')) AS ADDTFA
FROM prod_shs.[ACTIVITESCHEMA]_ADP01
WHERE ADADAV IN ('0','3')
GROUP BY 1,2;
ALTER TABLE w_ADP01 ADD CONSTRAINT w_ADP01_pkey PRIMARY KEY(ADDOSS);
UPDATE pmsi.p_rss_etat
SET date_facture = CASE WHEN ADDTFA >= date_sortie AND ADDTFA <> '20991231' THEN ADDTFA ELSE '20991231' END,
est_facture = CASE WHEN ADDTFA >= date_sortie AND ADDTFA <> '20991231' THEN '1' ELSE '0' END
FROM pmsi.p_rss
JOIN w_ADP01 ON ADDOSS = no_sejour_administratif
WHERE p_rss_etat.rss_id = p_rss.oid AND
(
date_facture IS DISTINCT FROM CASE WHEN ADDTFA >= date_sortie AND ADDTFA <> '20991231' THEN ADDTFA ELSE '20991231' END
OR
est_facture IS DISTINCT FROM CASE WHEN ADDTFA >= date_sortie AND ADDTFA <> '20991231' THEN '1' ELSE '0' END
);
UPDATE pmsi.p_rss_etat
SET date_facture = CASE WHEN ADDTFA >= date_sortie AND ADDTFA <> '20991231' THEN ADDTFA ELSE '20991231' END,
est_facture = CASE WHEN ADDTFA >= date_sortie AND ADDTFA <> '20991231' THEN '1' ELSE '0' END
FROM pmsi.p_rss
JOIN w_ADP01 ON ADDOSS2 = no_sejour_administratif
WHERE p_rss_etat.rss_id = p_rss.oid AND
(
date_facture IS DISTINCT FROM CASE WHEN ADDTFA >= date_sortie AND ADDTFA <> '20991231' THEN ADDTFA ELSE '20991231' END
OR
est_facture IS DISTINCT FROM CASE WHEN ADDTFA >= date_sortie AND ADDTFA <> '20991231' THEN '1' ELSE '0' END
);
UPDATE pmsi.p_rss_etat
SET est_groupe = '1', est_valide = '1'
WHERE est_facture = '1' AND
(est_groupe = '0' OR est_valide = '0') ;
UPDATE pmsi.p_rss_etat
SET date_groupage = date_facture
WHERE date_facture < date_groupage AND
date_facture <> '20991231' AND
date_groupage <> '20991231';
UPDATE pmsi.p_rss_etat
SET date_groupage = '20991231'
WHERE date_groupage <> '20991231' AND
est_groupe IN ('0','9');
UPDATE pmsi.p_rss
SET ghm_id = t_ghm_99Z98Z.oid,
ghm_production_id = t_ghm_99Z98Z.oid
FROM pmsi.p_rss_etat, pmsi.t_ghm, pmsi.t_ghm t_ghm_99Z98Z
WHERE p_rss.oid = p_rss_etat.rss_id AND
p_rss.ghm_id = t_ghm.oid AND
t_ghm_99Z98Z.code = '99Z98Z' AND
est_facture = '1' AND
t_ghm.code = '99Z99Z' AND
p_rss.oid NOT IN (
SELECT rss_id
FROM pmsi.p_rsf_detail
JOIN pmsi.t_prestations ON prestation_id = t_prestations.oid
WHERE t_prestations.code IN ('SE1', 'SE2', 'SE3', 'SE4', 'SE5', 'SE6', 'SE7', 'APE', 'AP2', 'FPI', 'FFM', 'ATU')
);
UPDATE pmsi.p_rss
SET ghm_id = 0,
ghm_production_id = 0
FROM pmsi.p_rss_etat, pmsi.t_ghm, pmsi.t_ghm t_ghm_99Z98Z
WHERE p_rss.oid = p_rss_etat.rss_id AND
p_rss.en_cours = '1' AND
p_rss.ghm_id = t_ghm.oid AND
t_ghm_99Z98Z.code = '99Z98Z' AND
est_facture = '1' AND
t_ghm.code = '99Z99Z' AND
p_rss.oid NOT IN (
SELECT rss_id
FROM pmsi.p_rsf_detail
JOIN pmsi.t_prestations ON prestation_id = t_prestations.oid
WHERE t_prestations.code IN ('SE1', 'SE2', 'SE3', 'SE4', 'SE5', 'SE6', 'SE7', 'APE', 'AP2', 'FPI', 'FFM', 'ATU')
);
UPDATE pmsi.p_rss
SET ghm_id = t_ghm_99Z99Z.oid,
ghm_production_id = t_ghm_99Z99Z.oid
FROM pmsi.p_rss_etat, pmsi.t_ghm, pmsi.t_ghm t_ghm_99Z99Z
WHERE p_rss.oid = p_rss_etat.rss_id AND
p_rss.ghm_id = t_ghm.oid AND
t_ghm_99Z99Z.code = '99Z99Z' AND
en_cours = '1' AND
t_ghm.code LIKE '90%';
UPDATE pmsi.p_rss
SET ghm_id = 0,
ghm_production_id = 0
FROM pmsi.p_rss_etat, pmsi.t_ghm
WHERE p_rss.oid = p_rss_etat.rss_id AND
p_rss.en_cours = '1' AND
p_rss.ghm_id = t_ghm.oid AND
est_facture = '1' AND
(t_ghm.code = '99Z99Z' OR ghm_id = 0) AND
p_rss.oid IN (
SELECT rss_id
FROM pmsi.p_rsf_detail
JOIN pmsi.t_prestations ON prestation_id = t_prestations.oid
WHERE t_prestations.code IN ('SE1', 'SE2', 'SE3', 'SE4', 'FFM', 'ATU')
);
UPDATE pmsi.p_rss
SET en_cours_etat = 'F'
FROM pmsi.p_rss_etat
WHERE p_rss.oid = p_rss_etat.rss_id AND
en_cours = '1' AND
en_cours_etat IS DISTINCT FROM 'F' AND
est_facture = 1 ;
]]></sqlcmd>
</NODE>
</NODE>
</ROOT>