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.
 
 

785 lines
28 KiB

<?xml version="1.0" encoding="ISO-8859-1"?>
<ROOT>
<NODE name="PMSICOMPLEMENTS" label="RECUPERATION DES DONNEES COMPLEMENTAIRES PMSI CERNER">
<NODE label="Parametres">
<sqlcmd><![CDATA[
/**********************************************************************************
* SPECIALITES MEDECINS *
**********************************************************************************/
INSERT INTO pmsi.t_specialites_medecin(code,texte)
SELECT
SP_CODE,
SP_LIB
FROM prod_cerner.SPECIALITE
LEFT JOIN pmsi.t_specialites_medecin on t_specialites_medecin.code = SP_CODE
WHERE t_specialites_medecin.code IS NULL
ORDER BY 1;
INSERT INTO pmsi.t_specialites_internes_medecin(code, texte)
SELECT
t_specialites_medecin.code::text || '..'::text,
t_specialites_medecin.texte
FROM
pmsi.t_specialites_medecin
LEFT JOIN pmsi.t_specialites_internes_medecin on t_specialites_internes_medecin.code = t_specialites_medecin.code::text || '..'::text
WHERE 1=1
AND t_specialites_medecin.oid <> 0
AND t_specialites_internes_medecin.code IS NULL
ORDER BY 1;
/**********************************************************************************
* MEDECINS *
**********************************************************************************/
INSERT INTO pmsi.t_medecins (code, nom, prenom, specialite_id, no_adeli, specialite_interne_id)
SELECT
INTERVENANT.IN_CODE as code
,INTERVENANT.IN_NOM as nom
,INTERVENANT.IN_PRENOM as prenom
,COALESCE(t_specialites_medecin.oid, 0) as specialite_id
,SUBSTR(COALESCE(INTERVENANT.IN_IDNATIONAL,''),1,9) as no_adeli
,COALESCE(t_specialites_internes_medecin.oid, 0) as specialite_interne_id
FROM
prod_cerner.INTERVENANT
LEFT JOIN pmsi.t_specialites_medecin ON t_specialites_medecin.code = IN_SPCODE
LEFT JOIN pmsi.t_specialites_internes_medecin ON (t_specialites_internes_medecin.code = IN_SPCODE || '..')
LEFT JOIN pmsi.t_medecins ON IN_CODE = t_medecins.code
WHERE t_medecins.code IS NULL;
/**********************************************************************************
* UNITES MEDICALES *
**********************************************************************************/
INSERT INTO pmsi.t_unites_medicales (code, texte)
SELECT
UF_CODE
,UF_LIB
FROM
prod_cerner.UF
LEFT JOIN pmsi.t_unites_medicales ON t_unites_medicales.code = UF.UF_CODE
WHERE
t_unites_medicales.code IS NULL
ORDER BY 1;
/**********************************************************************************
* UNITES FONCTIONNELLES *
**********************************************************************************/
INSERT INTO pmsi.t_unites_fonctionnelles (code, texte)
SELECT
UF_CODE
,UF_LIB
FROM
prod_cerner.UF
LEFT JOIN pmsi.t_unites_fonctionnelles ON t_unites_fonctionnelles.code = UF.UF_CODE
WHERE
t_unites_fonctionnelles.code IS NULL
ORDER BY 1;
]]></sqlcmd>
</NODE>
<NODE label="Unites medicales externes">
<sqlcmd><![CDATA[
WITH w_PASSAGE AS (
SELECT
p_rss.oid as rss_id
,(min(array[PASSAGE.SEA_UFCODE::text, to_char(PASSAGE.SEA_DATE, 'YYYY-MM-DD')]))[1] as um_code
FROM
[SCHEMA].p_rss_rum
join [SCHEMA].p_rss on p_rss.oid = p_rss_rum.rss_id
JOIN prod_cerner.HOSPITALISATION ON HOSPITALISATION.HO_NUM = p_rss.no_sejour_administratif
JOIN prod_cerner.PASSAGE ON PASSAGE.SEA_HONUM = HOSPITALISATION.HO_NUM
WHERE 1=1
AND p_rss.import_id = [IMPORT_ID]
AND p_rss.ghm_id = 0
AND p_rss_rum.date_entree = PASSAGE.SEA_DATE
GROUP BY 1
)
UPDATE [SCHEMA].p_rss_rum SET
unite_medicale = t_unites_medicales.code
,unite_medicale_id = t_unites_medicales.oid
FROM
w_PASSAGE
JOIN pmsi.t_unites_medicales ON t_unites_medicales.code = w_PASSAGE.um_code
WHERE
w_PASSAGE.rss_id = p_rss_rum.rss_id;
-- correction des no_rum manquants dans la table des actes
UPDATE [SCHEMA].p_rss_actes SET
no_rum = 1
FROM
[SCHEMA].p_rss
WHERE
p_rss.oid = p_rss_actes.rss_id
AND p_rss.ghm_id = 0
AND no_rum is distinct from 1;
-- Mise à jour des UM dans la table des actes
UPDATE [SCHEMA].p_rss_actes SET
unite_medicale = p_rss_rum.unite_medicale
,unite_medicale_id = p_rss_rum.unite_medicale_id
FROM
[SCHEMA].p_rss_rum
JOIN [SCHEMA].p_rss ON p_rss.oid = p_rss_rum.rss_id
WHERE 1=1
AND p_rss.ghm_id = 0
AND p_rss.import_id = [IMPORT_ID]
AND p_rss_actes.no_rum = p_rss_rum.no_rum
AND p_rss_actes.rss_id = p_rss_rum.rss_id
AND p_rss_actes.unite_medicale_id != p_rss_rum.unite_medicale_id;
-- Mise à jour de l'unité principale dans le RSS
UPDATE [SCHEMA].p_rss SET
unite_medicale_principale_id = p_rss_rum.unite_medicale_id
FROM
[SCHEMA].p_rss_rum
WHERE 1=1
AND p_rss.oid = p_rss_rum.rss_id
AND p_rss.import_id = [IMPORT_ID]
AND p_rss.ghm_id = 0
AND p_rss_rum.no_rum = 1
AND p_rss.unite_medicale_principale_id = 0;
]]></sqlcmd>
</NODE>
<NODE label="UF d'execution externes et medecins executants">
<sqlcmd><![CDATA[
WITH w_PASSAGE_CDAM AS (
SELECT
p_rss.oid as rss_id
--p_rss.no_sejour_administratif
,PASSAGE_CDAM.CDAM_UFCODE as um_code
,substr(PASSAGE_CDAM.CDAM_DGCODE, 1, 7) as acte_code
,PASSAGE_CDAM.CDAM_CCAM_ACTIVITE as activite_ccam
,PASSAGE_CDAM.CDAM_DATE as acte_date
,PASSAGE_CDAM.CDAM_CCAM_ASSNOPREV as acte_asso_non_prevue
,MAX(PASSAGE_CDAM.CDAM_UFXCODE) as uf_code
,MAX(PASSAGE_CDAM.CDAM_INXCODE) as medecin_code
FROM
[SCHEMA].p_rss_actes
join [SCHEMA].p_rss on p_rss.oid = p_rss_actes.rss_id
JOIN pmsi.t_actes on t_actes.oid = p_rss_actes.acte_id
JOIN prod_cerner.HOSPITALISATION ON HOSPITALISATION.HO_NUM = p_rss.no_sejour_administratif
JOIN prod_cerner.PASSAGE_CDAM ON PASSAGE_CDAM.CDAM_HONUM = HOSPITALISATION.HO_NUM
WHERE 1=1
AND p_rss.import_id = [IMPORT_ID]
AND p_rss.ghm_id = 0
AND substr(PASSAGE_CDAM.CDAM_DGCODE, 1,7) = t_actes.code
AND p_rss_actes.date_acte = PASSAGE_CDAM.CDAM_DATE
AND p_rss_actes.association_nonprevue_ccam = PASSAGE_CDAM.CDAM_CCAM_ASSNOPREV
AND PASSAGE_CDAM.CDAM_CCAM_ACTIVITE = p_rss_actes.activite_ccam
GROUP BY 1,2,3,4,5,6
)
UPDATE [SCHEMA].p_rss_actes SET
medecin_id = COALESCE(t_medecins.oid, 0)
,unite_fonctionnelle_id = COALESCE(t_unites_fonctionnelles.oid, 0)
FROM
w_PASSAGE_CDAM
LEFT JOIN pmsi.t_medecins on t_medecins.code = w_PASSAGE_CDAM.medecin_code
LEFT JOIN pmsi.t_unites_fonctionnelles on t_unites_fonctionnelles.code = w_PASSAGE_CDAM.uf_code
LEFT JOIN pmsi.t_actes on t_actes.code = w_PASSAGE_CDAM.acte_code
WHERE (1 !=1
OR p_rss_actes.medecin_id = 0
OR p_rss_actes.medecin_id IS NULL
OR p_rss_actes.unite_fonctionnelle_id = 0
OR p_rss_actes.unite_fonctionnelle_id IS NULL
)
AND p_rss_actes.rss_id = w_PASSAGE_CDAM.rss_id
AND p_rss_actes.unite_medicale = w_PASSAGE_CDAM.um_code
AND p_rss_actes.acte_id = t_actes.oid
AND p_rss_actes.date_acte = w_PASSAGE_CDAM.acte_date
AND p_rss_actes.activite_ccam = w_PASSAGE_CDAM.activite_ccam
AND p_rss_actes.association_nonprevue_ccam = w_PASSAGE_CDAM.acte_asso_non_prevue;
]]></sqlcmd>
</NODE>
<NODE label="Identites">
<sqlcmd><![CDATA[
DROP TABLE IF EXISTS w_PASSAGE;
CREATE TEMP TABLE w_PASSAGE AS
SELECT
PASSAGE.SEA_DATE::date,
HOSPITALISATION.HO_NUM,
MALADE.MA_DATENAI::date,
MALADE.MA_SEXE
FROM
prod_cerner.PASSAGE
JOIN prod_cerner.HOSPITALISATION ON PASSAGE.SEA_HONUM = HOSPITALISATION.HO_NUM
JOIN prod_cerner.MALADE ON MALADE.MA_NUMDOS = HOSPITALISATION.HO_MANUMDOS
WHERE
PASSAGE.SEA_DATE::date BETWEEN '[IMPORT_ANNEE]0101'::date AND '[IMPORT_ANNEE]1231'::date
GROUP BY 1,2,3,4
;
CREATE INDEX w_PASSAGE_i1
ON w_PASSAGE
USING btree
(HO_NUM)
;
UPDATE [SCHEMA].p_rss SET
no_sejour_administratif = w_PASSAGE.HO_NUM
FROM
[SCHEMA].p_rsf_total,
w_PASSAGE
WHERE 1=1
AND p_rss.ghm_id = 0
AND p_rsf_total.rss_id = p_rss.oid
AND p_rsf_total.no_facture = p_rss.no_sejour_administratif
AND p_rss.date_entree = w_PASSAGE.SEA_DATE
AND p_rss.date_naissance = w_PASSAGE.MA_DATENAI
AND p_rss.sexe = w_PASSAGE.MA_SEXE
AND p_rss.no_sejour_administratif != w_PASSAGE.HO_NUM
;
UPDATE [SCHEMA].p_identites SET
nom = MALADE.MA_NOM1
,prenom = MALADE.MA_PRENOM
,nom_naissance = MALADE.MA_NOM2
FROM [SCHEMA].p_rss
JOIN prod_cerner.HOSPITALISATION ON HOSPITALISATION.HO_NUM = p_rss.no_sejour_administratif
JOIN prod_cerner.PASSAGE ON PASSAGE.SEA_HONUM = HOSPITALISATION.HO_NUM
AND PASSAGE.SEA_DATE = p_rss.date_entree
JOIN prod_cerner.MALADE ON MALADE.MA_NUMDOS = HOSPITALISATION.HO_MANUMDOS
WHERE
p_identites.rss_id = p_rss.oid
AND nom like 'RSS %'
;
UPDATE [SCHEMA].p_rss SET
no_patient = HO_MANUMDOS
FROM prod_cerner.HOSPITALISATION
WHERE 1=1
AND HO_NUM = p_rss.no_sejour_administratif
AND no_patient IS DISTINCT FROM HO_MANUMDOS
AND no_patient = 0
;
]]></sqlcmd>
</NODE>
<NODE label="Medecins RSS externes">
<sqlcmd><![CDATA[
-- Il se peut que l'attibution des médecins par l'acte n'ait pas pu marcher antérieurement.
-- On retente avec les médecins exécutants de la table SERVEUR_CDAM,
-- séjours externes uniquement
-- Les lignes avec SNGAP_TYPE = 'C' sont des créations
-- Les lignes avec SNGAP_TYPE = 'M' sont des modifications
-- Il faut donc prendre pour chaque SEJOUR/ACTE/DATE_ACTE/ACTIVITE_CCAM la donnée la plus récente : max(SCDAM_MAJ)
DROP TABLE IF EXISTS w_SERVEUR_CDAM;
CREATE TEMP TABLE w_SERVEUR_CDAM AS
SELECT
SERVEUR_CDAM.SCDAM_HONUM
,substr(SERVEUR_CDAM.SCDAM_DGCODE,1,7) as SCDAM_DGCODE
,SERVEUR_CDAM.SCDAM_DATE
,SERVEUR_CDAM.SCDAM_CCAM_ACTIVITE
,max(ARRAY[to_char(SCDAM_MAJ, 'YYYYMMDD'), SCDAM_INXCODE::text]) as values
FROM
prod_cerner.SERVEUR_CDAM
WHERE 1=1
GROUP BY 1,2,3,4;
-- Mise a jour des médecins exécutants avec la table précédemment calculée
WITH w_act AS (
SELECT
p_rss.oid AS rss_id
,w_SERVEUR_CDAM.SCDAM_DATE as date_acte
,t_actes.oid as acte_id
,w_SERVEUR_CDAM.SCDAM_CCAM_ACTIVITE as activite_ccam
,t_medecins.oid as medecin_id
FROM
w_SERVEUR_CDAM
JOIN [SCHEMA].p_rss ON w_SERVEUR_CDAM.SCDAM_HONUM = p_rss.no_sejour_administratif
JOIN [SCHEMA].p_rss_actes ON p_rss_actes.rss_id = p_rss.oid
AND p_rss_actes.date_acte = w_SERVEUR_CDAM.SCDAM_DATE
AND p_rss_actes.activite_ccam = w_SERVEUR_CDAM.SCDAM_CCAM_ACTIVITE
JOIN pmsi.t_actes on t_actes.oid = p_rss_actes.acte_id
AND t_actes.code = substr(w_SERVEUR_CDAM.SCDAM_DGCODE, 1, 7)
JOIN pmsi.t_medecins ON t_medecins.code = w_SERVEUR_CDAM.values[2]
WHERE 1=1
AND p_rss_actes.medecin_id = 0
AND p_rss.ghm_id = 0
GROUP BY 1,2,3,4,5
)
UPDATE [SCHEMA].p_rss_actes SET
medecin_id = w_act.medecin_id
FROM
w_act
WHERE 1=1
AND p_rss_actes.rss_id = w_act.rss_id
AND p_rss_actes.acte_id = w_act.acte_id
AND p_rss_actes.activite_ccam = w_act.activite_ccam
AND p_rss_actes.date_acte = w_act.date_acte;
-- Médecin de l'acte avec le plus fort ICR par RSS et par RUM
DROP TABLE IF EXISTS w_max_icr;
CREATE TEMP TABLE w_max_icr AS
SELECT
rss_id,
no_rum,
(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 <> '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]
)) AS icr_medecin
FROM
[SCHEMA].p_rss_actes
JOIN pmsi.t_actes_c ON p_rss_actes.acte_id = t_actes_c.oid
GROUP BY 1,2
ORDER BY 1,2;
UPDATE [SCHEMA].p_rss SET
medecin_rss_id = subview.medecin_id
FROM
(
SELECT
rss_id,
icr_medecin[2]::bigint as medecin_id
FROM
w_max_icr
where no_rum = 1
) subview
WHERE 1=1
AND p_rss.ghm_id = 0
AND subview.rss_id = p_rss.oid
AND p_rss.medecin_rss_id IS DISTINCT FROM subview.medecin_id;
DROP TABLE IF EXISTS w_max_icr;
DROP TABLE IF EXISTS w_SERVEUR_CDAM;
-- Si pas d'acte, on prend le médecin exécutant de la consult
-- Le code de prestation dans la table SERVEUR_NGAP doit être "traduit" à l'aide de la table CODE_TARIF
-- Car il n'est pas toujours conforme à ce qu'il y a dans les RSF-ACE
with w_SERVEUR_NGAP AS
(
SELECT
SNGAP_HONUM,
SNGAP_DATE,
COALESCE(
MAX(CASE WHEN CT_LET = 'CS' THEN array[to_char(SNGAP_MAJ, 'YYYYMMDD'), SNGAP_INXCODE::text] ELSE NULL END),
MAX(CASE WHEN CT_LET = 'CSC' THEN array[to_char(SNGAP_MAJ, 'YYYYMMDD'), SNGAP_INXCODE::text] ELSE NULL END),
MAX(CASE WHEN CT_LET = 'C' THEN array[to_char(SNGAP_MAJ, 'YYYYMMDD'), SNGAP_INXCODE::text] ELSE NULL END),
MAX(CASE WHEN CT_LET = 'CNPSY' THEN array[to_char(SNGAP_MAJ, 'YYYYMMDD'), SNGAP_INXCODE::text] ELSE NULL END),
MAX(CASE WHEN CT_LET = 'C2PSY' THEN array[to_char(SNGAP_MAJ, 'YYYYMMDD'), SNGAP_INXCODE::text] ELSE NULL END),
MAX(CASE WHEN CT_LET = 'CNP' THEN array[to_char(SNGAP_MAJ, 'YYYYMMDD'), SNGAP_INXCODE::text] ELSE NULL END),
MAX(CASE WHEN CT_LET = 'ATM' THEN array[to_char(SNGAP_MAJ, 'YYYYMMDD'), SNGAP_INXCODE::text] ELSE NULL END),
MAX(CASE WHEN CT_LET = 'FTN' THEN array[to_char(SNGAP_MAJ, 'YYYYMMDD'), SNGAP_INXCODE::text] ELSE NULL END),
MAX(CASE WHEN CT_LET = 'AMC' THEN array[to_char(SNGAP_MAJ, 'YYYYMMDD'), SNGAP_INXCODE::text] ELSE NULL END),
MAX(CASE WHEN CT_LET = 'AMI' THEN array[to_char(SNGAP_MAJ, 'YYYYMMDD'), SNGAP_INXCODE::text] ELSE NULL END),
MAX(CASE WHEN CT_LET = 'TB' THEN array[to_char(SNGAP_MAJ, 'YYYYMMDD'), SNGAP_INXCODE::text] ELSE NULL END),
MAX(CASE WHEN CT_LET = 'B' THEN array[to_char(SNGAP_MAJ, 'YYYYMMDD'), SNGAP_INXCODE::text] ELSE NULL END),
MAX(CASE WHEN CT_LET = 'G' THEN array[to_char(SNGAP_MAJ, 'YYYYMMDD'), SNGAP_INXCODE::text] ELSE NULL END)
) as SNGAP_INXCODE
FROM
prod_cerner.SERVEUR_NGAP
LEFT JOIN prod_cerner.CODE_TARIF ON CODE_TARIF.CT_CODE = SERVEUR_NGAP.SNGAP_CTCODE
WHERE 1=1
AND CODE_TARIF.CT_LET IN ('C', 'CS', 'CNP', 'CNPSY', 'C2PSY', 'CSC', 'AMC', 'ATM', 'AMI', 'FTN', 'TB', 'B', 'G')
GROUP BY 1,2
)
UPDATE [SCHEMA].p_rss SET
medecin_rss_id = t_medecins.oid
FROM
w_SERVEUR_NGAP,
[SCHEMA].p_rsf_detail,
pmsi.t_medecins
WHERE 1=1
AND p_rss.no_sejour_administratif = w_SERVEUR_NGAP.SNGAP_HONUM
AND p_rsf_detail.rss_id = p_rss.oid
AND p_rsf_detail.date_debut = w_SERVEUR_NGAP.SNGAP_DATE
AND t_medecins.code = w_SERVEUR_NGAP.SNGAP_INXCODE[2]
AND ghm_id = 0
AND medecin_rss_id = 0;
-- Si non, on prend le médecin responsable du passage
with w_PASSAGE AS (
SELECT
p_rss.oid as rss_id
,MAX(PASSAGE.SEA_INCODE) as med_code
FROM
[SCHEMA].p_rss
JOIN prod_cerner.HOSPITALISATION ON HOSPITALISATION.HO_NUM = p_rss.no_sejour_administratif
JOIN prod_cerner.PASSAGE ON PASSAGE.SEA_HONUM = HOSPITALISATION.HO_NUM
WHERE 1=1
AND p_rss.import_id = [IMPORT_ID]
AND p_rss.ghm_id = 0
AND p_rss.medecin_rss_id = 0
AND p_rss.date_entree = PASSAGE.SEA_DATE
GROUP BY p_rss.oid
)
UPDATE [SCHEMA].p_rss SET
medecin_rss_id = t_medecins.oid
FROM
w_PASSAGE
JOIN pmsi.t_medecins ON t_medecins.code = w_PASSAGE.med_code
WHERE
p_rss.oid = w_PASSAGE.rss_id
;
]]></sqlcmd>
</NODE>
</NODE>
<NODE name="PMSIENCOURS" label="RECUPERATION DES DOSSIERS PMSI EN-COURS CERNER">
<NODE label="Paramètres">
<sqlcmd><![CDATA[
DROP TABLE IF EXISTS w_finess;
CREATE TEMP TABLE w_finess AS
SELECT
ETABLISSEMENT.ET_CODE
,ETABLISSEMENT.ET_FINESS
FROM
prod_cerner.ETABLISSEMENT
WHERE
ETABLISSEMENT.ET_FINESS = '[FINESS]';
DROP TABLE IF EXISTS w_SELECT;
CREATE TEMP TABLE w_SELECT AS
SELECT
HOSPITALISATION.HO_NUM
,HOSPITALISATION.HO_DDEB
,HOSPITALISATION.HO_DFIN
FROM
prod_cerner.HOSPITALISATION
JOIN prod_cerner.REGROUPEMENT ON REGROUPEMENT.RE_CODE = HOSPITALISATION.HO_RECODE
JOIN prod_cerner.POSTE_GEST ON POSTE_GEST.PGS_CODE = HOSPITALISATION.HO_PGSCODE
LEFT JOIN pmsi.p_rss ON p_rss.no_sejour_administratif = HOSPITALISATION.HO_NUM
WHERE 1=1
AND POSTE_GEST.PGS_CODE = 'RS'
AND REGROUPEMENT.RE_TYPE = 'H'
AND HOSPITALISATION.HO_PREENT IS DISTINCT FROM 'X'
AND HOSPITALISATION.HO_DFIN <= now()
AND HOSPITALISATION.HO_DFIN >= '[ANNEE]0101'
AND p_rss.no_sejour_administratif IS NULL;
]]></sqlcmd>
</NODE>
<NODE label="RSS">
<sqlcmd><![CDATA[
]]></sqlcmd>
</NODE>
<NODE label="Identités">
<sqlcmd><![CDATA[
]]></sqlcmd>
</NODE>
<NODE label="Rum">
<sqlcmd><![CDATA[
]]></sqlcmd>
</NODE>
<NODE label="Diagnostics">
<sqlcmd><![CDATA[
]]></sqlcmd>
</NODE>
<NODE label="Actes">
<sqlcmd><![CDATA[
]]></sqlcmd>
</NODE>
<NODE label="LPP">
<sqlcmd><![CDATA[
-- Détection des dernières modifs
-- Les lignes avec SNGAP_TYPE = 'C' sont des créations
-- Les lignes avec SNGAP_TYPE = 'M' sont des modifications
-- Les lignes avec SNGAP_TYPE = 'S' sont des suppressions
-- Attention, il peut y avoir plusieurs créations pour le même code LPP
-- La clé de distinction est sngap_id
-- Il faut donc prendre pour chaque SEJOUR/SNGAP_ID/LPP la donnée la plus récente (SNGAP_MAJ), M plutot que C
-- Il faut au préalable repérer les entées supprimées
DROP TABLE IF EXISTS w_delete; CREATE TEMP TABLE w_delete AS
SELECT SNGAP_ID FROM prod_cerner.serveur_ngap WHERE SNGAP_TYPE = 'S' GROUP BY 1;
-- On créé en suite les cumuls en ne tenant pas compte des entrées supprimées
DROP TABLE IF EXISTS w_last_modifs;
CREATE TEMP TABLE w_last_modifs AS
SELECT
SERVEUR_NGAP.SNGAP_HONUM
,SERVEUR_NGAP.SNGAP_ID
,SERVEUR_NGAP.SNGAP_LPP
,COALESCE(LPP.LPP_LIB, SERVEUR_NGAP.SNGAP_LPP) as LPP_LIB
,max(ARRAY[to_char(SERVEUR_NGAP.SNGAP_MAJ, 'YYYYMMDDHH24MISS'), SERVEUR_NGAP.SNGAP_TYPE, to_char(SERVEUR_NGAP.SNGAP_DATE, 'YYYYMMDDHH24MISS'), SERVEUR_NGAP.SNGAP_RESULT::text, SERVEUR_NGAP.SNGAP_PRIX_ACHAT::text]) as values
FROM
prod_cerner.SERVEUR_NGAP
LEFT JOIN prod_cerner.LPP ON LPP.LPP_ID = SERVEUR_NGAP.SNGAP_LPP
LEFT JOIN w_delete ON w_delete.SNGAP_ID = SERVEUR_NGAP.SNGAP_ID
WHERE 1=1
AND SERVEUR_NGAP.SNGAP_LPP != ''
AND w_delete.SNGAP_ID IS NULL
GROUP BY 1,2,3,4
;
CREATE INDEX w_last_modifs_i1
ON w_last_modifs
USING btree
(SNGAP_HONUM)
;
-- récupération des LPP en cours
DROP TABLE IF EXISTS w_SERVEUR_NGAP;
CREATE TEMP TABLE w_SERVEUR_NGAP AS
SELECT
w_last_modifs.SNGAP_HONUM
,to_date(w_last_modifs.values[3], 'YYYYMMDDHH24MISS') AS SNGAP_DATE
,w_last_modifs.values[4]::numeric AS SNGAP_RESULT
,w_last_modifs.values[5]::numeric AS SNGAP_PRIX_ACHAT
,w_last_modifs.SNGAP_LPP
,w_last_modifs.LPP_LIB
,p_rss.no_rss
,p_rss.oid AS rss_id
,p_rss.finess
FROM
pmsi.p_rss
JOIN w_last_modifs ON p_rss.no_sejour_administratif = w_last_modifs.SNGAP_HONUM
WHERE 1=1
AND p_rss.en_cours = '1'
;
-- Ajout des codes LPP inexistants dans la nomenclature CTI
INSERT INTO pmsi.t_lpp (code, texte, texte_court)
SELECT
SNGAP_LPP
,'@'::text || LPP_LIB::text
,'@'::text || LPP_LIB::text
FROM
w_SERVEUR_NGAP
LEFT JOIN pmsi.t_lpp ON t_lpp.code = w_SERVEUR_NGAP.SNGAP_LPP
WHERE
t_lpp.code IS NULL
GROUP BY 1,2,3;
-- Ajout des LPP
INSERT INTO pmsi.p_rss_lpp (
finess
,no_rss
,date_lpp
,lpp_id
,nombre
,prix_unitaire
,montant_facture
,rss_id)
SELECT
w_SERVEUR_NGAP.finess
,w_SERVEUR_NGAP.no_rss
,w_SERVEUR_NGAP.SNGAP_DATE
,t_lpp.oid
,least(999999, w_SERVEUR_NGAP.SNGAP_RESULT)
,w_SERVEUR_NGAP.SNGAP_PRIX_ACHAT
,w_SERVEUR_NGAP.SNGAP_RESULT * w_SERVEUR_NGAP.SNGAP_PRIX_ACHAT
,w_SERVEUR_NGAP.rss_id
FROM
w_SERVEUR_NGAP
JOIN pmsi.t_lpp ON t_lpp.code = w_SERVEUR_NGAP.SNGAP_LPP;
-- Ajout des lignes de prestations afin de mettre à jour le compteur p_rss.dmi_facture utilisé dans la consolidation pour détecter les modifications
INSERT INTO pmsi.p_rsf_detail (
finess, rss_id, no_rss, date_debut, date_fin, nombre, prix_unitaire, base_remboursement, taux_remboursement, sejour_facture, sejour_remboursable, "type", no_rum, prestation_id)
SELECT
w_SERVEUR_NGAP.finess
,w_SERVEUR_NGAP.rss_id
,w_SERVEUR_NGAP.no_rss
,w_SERVEUR_NGAP.SNGAP_DATE as date_debut
,w_SERVEUR_NGAP.SNGAP_DATE as date_fin
,least(999999, w_SERVEUR_NGAP.SNGAP_RESULT) as nombre
,w_SERVEUR_NGAP.SNGAP_PRIX_ACHAT as prix_unitaire
,round(w_SERVEUR_NGAP.SNGAP_RESULT * w_SERVEUR_NGAP.SNGAP_PRIX_ACHAT, 2) as base_remboursement
,100 as taux_remboursement
,w_SERVEUR_NGAP.SNGAP_RESULT as sejour_facture
,w_SERVEUR_NGAP.SNGAP_RESULT as sejour_remboursable
,'B' as "type"
,1 as no_rum
,t_prestations.oid as prestation_id
FROM
w_SERVEUR_NGAP,
pmsi.t_prestations
WHERE
t_prestations.code = 'PII';
DROP TABLE IF EXISTS w_last_modifs;
DROP TABLE IF EXISTS w_SERVEUR_NGAP;
]]></sqlcmd>
</NODE>
<NODE label="UCD">
<sqlcmd><![CDATA[
-- Détection des dernières modifs
-- Les lignes avec SNGAP_TYPE = 'C' sont des créations
-- Les lignes avec SNGAP_TYPE = 'M' sont des modifications
-- Les lignes avec SNGAP_TYPE = 'S' sont des suppressions
-- SNGAP_ID est la clé pour chaque UCD
-- Il faut donc prendre pour chaque SEJOUR/UCD/SNGAP_ID la donnée la plus récente (SNGAP_MAJ), M plutot que C
-- Il faut au préalable repérer les entées supprimées
DROP TABLE IF EXISTS w_delete; CREATE TEMP TABLE w_delete AS
SELECT SNGAP_ID FROM prod_cerner.serveur_ngap WHERE SNGAP_TYPE = 'S' GROUP BY 1;
-- On créé en suite les cumuls en ne tenant pas compte des entrées supprimées
DROP TABLE IF EXISTS w_last_modifs;
CREATE TEMP TABLE w_last_modifs AS
SELECT
SERVEUR_NGAP.SNGAP_HONUM
,SERVEUR_NGAP.SNGAP_ID
,MEDICAMENTS.MED_UCD
,COALESCE(MEDICAMENTS.MED_DESIGNATION::text, MEDICAMENTS.MED_UCD::text) as MED_DESIGNATION
,max(ARRAY[to_char(SERVEUR_NGAP.SNGAP_MAJ, 'YYYYMMDDHH24MISS'), SERVEUR_NGAP.SNGAP_TYPE, to_char(SERVEUR_NGAP.SNGAP_DATE, 'YYYYMMDDHH24MISS'), SERVEUR_NGAP.SNGAP_RESULT::text, SERVEUR_NGAP.SNGAP_PRIX_ACHAT::text]) as values
FROM
prod_cerner.SERVEUR_NGAP
LEFT JOIN prod_cerner.MEDICAMENTS ON MEDICAMENTS.MED_ID = SERVEUR_NGAP.SNGAP_MEDID
LEFT JOIN w_delete ON w_delete.SNGAP_ID = SERVEUR_NGAP.SNGAP_ID
WHERE 1=1
AND SERVEUR_NGAP.SNGAP_UCD != ''
AND w_delete.SNGAP_ID IS NULL
GROUP BY 1,2,3,4
;
CREATE INDEX w_last_modifs_i1
ON w_last_modifs
USING btree
(SNGAP_HONUM)
;
-- récupération des UCD en cours
DROP TABLE IF EXISTS w_SERVEUR_NGAP;
CREATE TEMP TABLE w_SERVEUR_NGAP AS
SELECT
w_last_modifs.SNGAP_HONUM
,to_date(w_last_modifs.values[3], 'YYYYMMDDHH24MISS') AS SNGAP_DATE
,w_last_modifs.values[4]::numeric AS SNGAP_RESULT
,w_last_modifs.values[5]::numeric AS SNGAP_PRIX_ACHAT
,w_last_modifs.MED_UCD
,w_last_modifs.MED_DESIGNATION
,p_rss.no_rss
,p_rss.oid AS rss_id
,p_rss.finess
FROM
pmsi.p_rss
JOIN w_last_modifs ON p_rss.no_sejour_administratif = w_last_modifs.SNGAP_HONUM
WHERE 1=1
AND p_rss.en_cours = '1'
;
-- Ajout des codes UCD inexistants dans la nomenclature CTI
INSERT INTO pmsi.t_ucd (code, texte, texte_court)
SELECT
MED_UCD
,'@'::text || MED_DESIGNATION::text
,'@'::text || MED_DESIGNATION::text
FROM
w_SERVEUR_NGAP
LEFT JOIN pmsi.t_ucd ON t_ucd.code = w_SERVEUR_NGAP.MED_UCD
WHERE
t_ucd.code IS NULL
GROUP BY 1,2,3;
-- Ajout des UCD
INSERT INTO pmsi.p_rss_ucd (
finess
,no_rss
,date_ucd
,ucd_id
,nombre
,prix_unitaire_achat
,montant_facture
,rss_id)
SELECT
w_SERVEUR_NGAP.finess
,w_SERVEUR_NGAP.no_rss
,w_SERVEUR_NGAP.SNGAP_DATE
,t_ucd.oid
,w_SERVEUR_NGAP.SNGAP_RESULT
,w_SERVEUR_NGAP.SNGAP_PRIX_ACHAT
,w_SERVEUR_NGAP.SNGAP_RESULT * w_SERVEUR_NGAP.SNGAP_PRIX_ACHAT
,w_SERVEUR_NGAP.rss_id
FROM
w_SERVEUR_NGAP
JOIN pmsi.t_ucd ON t_ucd.code = w_SERVEUR_NGAP.MED_UCD;
-- Ajout des lignes de prestations afin de mettre à jour le compteur p_rss.phc_facture utilisé dans la consolidation pour détecter les modifications
INSERT INTO pmsi.p_rsf_detail (
finess, rss_id, no_rss, date_debut, date_fin, nombre, prix_unitaire, base_remboursement, taux_remboursement, sejour_facture, sejour_remboursable, "type", no_rum, prestation_id)
SELECT
w_SERVEUR_NGAP.finess
,w_SERVEUR_NGAP.rss_id
,w_SERVEUR_NGAP.no_rss
,w_SERVEUR_NGAP.SNGAP_DATE as date_debut
,w_SERVEUR_NGAP.SNGAP_DATE as date_fin
,w_SERVEUR_NGAP.SNGAP_RESULT as nombre
,w_SERVEUR_NGAP.SNGAP_PRIX_ACHAT as prix_unitaire
,round(w_SERVEUR_NGAP.SNGAP_RESULT * w_SERVEUR_NGAP.SNGAP_PRIX_ACHAT, 2) as base_remboursement
,100 as taux_remboursement
,w_SERVEUR_NGAP.SNGAP_RESULT as sejour_facture
,w_SERVEUR_NGAP.SNGAP_RESULT as sejour_remboursable
,'B' as "type"
,1 as no_rum
,t_prestations.oid as prestation_id
FROM
w_SERVEUR_NGAP,
pmsi.t_prestations
WHERE
t_prestations.code = 'PHH';
DROP TABLE IF EXISTS w_last_modifs;
DROP TABLE IF EXISTS w_SERVEUR_NGAP;
]]></sqlcmd>
</NODE>
<NODE label="Factures">
<sqlcmd><![CDATA[
]]></sqlcmd>
</NODE>
</NODE>
<NODE name="PMSIETAT" label="RECUPERATION ETAT DES DOSSIERS">
<NODE label="Initialisation">
<sqlcmd><![CDATA[
]]></sqlcmd>
</NODE>
<NODE label="Etat des dossiers">
<sqlcmd><![CDATA[
]]></sqlcmd>
</NODE>
</NODE>
</ROOT>