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.
 
 

182 lines
6.4 KiB

return: text
lang: plpgsql
parameters:
p0:
type: bigint
name: i_import_id
default: "0"
src: |
DECLARE
-- i_import_id = 0 : traite tous les RSS
-- i_import_id = -1 : traite les dossiers non transmis
-- i_import_id = n : traite les RSS de l'import n
request TEXT;
result TEXT;
cond TEXT := '';
new_rows integer;
BEGIN
/****************************************
* Supression des anciennes générations *
****************************************/
-- Tous les RSS
IF ($1 = 0) THEN
RAISE NOTICE 'Traitement de tous les RSS';
TRUNCATE pmsi.p_rss_sae;
cond := '';
-- RSS d'un import spécifique
ELSIF ($1 > 0) THEN
RAISE NOTICE '%', 'Traitement des RSS de l''import ' || $1;
-- Supprime les RSS de l'import spécifié
DELETE FROM pmsi.p_rss_sae where import_id = $1;
-- Suprime les RSS compris dans la période de l'import spécifié
DELETE FROM pmsi.p_rss_sae
USING
pmsi.p_rss,
pmsi.p_imports
WHERE 1=1
AND p_imports.oid = $1
AND p_rss.oid = p_rss_sae.rss_id
AND p_rss.en_cours = '0'
AND p_rss.date_sortie BETWEEN p_imports.date_debut AND p_imports.date_fin;
cond := ' AND p_rss.import_id = ' || $1;
-- RSS non transmis
ELSE
RAISE NOTICE 'Traitement des RSS non transmis';
DELETE FROM pmsi.p_rss_sae where import_id = $1;
cond := ' AND p_rss.en_cours = ''1''';
END IF;
/**************************
* Calcul des indicateurs *
**************************/
RAISE NOTICE 'Construction de la table de travail';
request = '
DROP TABLE IF EXISTS w_rss_sae; CREATE TEMP TABLE w_rss_sae AS
SELECT
p_rss.oid as rss_id
,p_rss.import_id
,count(p_rss_rum.rss_id) as nb_rum
,MAX(CASE WHEN p_rss.mode_entree = ''8'' AND p_rss.mode_sortie = ''8'' AND t_ghm.code != ''15Z10E'' AND t_diagnostics.code IN (''Z380'', ''Z383'', ''Z386'') THEN 1 ELSE 0 END) AS rss_bebe
,MAX(CASE WHEN t_types_autorisations.code = ''51'' THEN 1 ELSE 0 END) AS rss_neuro
,count(CASE WHEN t_modes_hospitalisation.code = ''HC'' OR t_modes_hospitalisation.code = ''HM'' AND p_rss_rum.duree_sejour > 0 THEN p_rss_rum.rss_id ELSE NULL END) as nb_rum_hc
,count(CASE WHEN t_modes_hospitalisation.code = ''HM'' AND p_rss_rum.duree_sejour = 0 THEN p_rss_rum.rss_id ELSE NULL END) as nb_rum_hm0
,count(CASE WHEN t_modes_hospitalisation.code = ''HP'' THEN p_rss_rum.rss_id ELSE NULL END) as nb_rum_hp
,(max(array[p_rss_rum.duree_sejour * 1000 - p_rss_rum.no_rum, t_disciplines_sae.oid]))[2] as rss_discipline_id
,NULL::text[] as dr_codes
,NULL::text[] as da_codes
,NULL::text[] as actes_codes
,array_agg(DISTINCT t_types_autorisations.code) as aut_codes
FROM
pmsi.p_rss
JOIN pmsi.t_ghm on t_ghm.oid = p_rss.ghm_id
JOIN pmsi.t_diagnostics ON t_diagnostics.oid = p_rss.diagnostic_principal_id
JOIN pmsi.p_rss_rum ON p_rss_rum.rss_id = p_rss.oid
JOIN pmsi.t_unites_medicales ON t_unites_medicales.oid = p_rss_rum.unite_medicale_id
JOIN pmsi.t_types_autorisations ON t_types_autorisations.code = t_unites_medicales.type_autorisation
JOIN pmsi.t_modes_hospitalisation ON t_modes_hospitalisation.oid = t_types_autorisations.mode_hospitalisation_id
JOIN pmsi.t_disciplines_sae ON t_disciplines_sae.oid = t_types_autorisations.discipline_sae_id
WHERE 1=1
AND ghm_id > 0
' || cond || '
GROUP BY 1,2;';
EXECUTE request;
-- Les diagnostics et les actes sont ajoutés a posteriori pour éviter de générer des tableaux remplis de NULL
RAISE NOTICE 'Ajout des diagnostcs relies';
WITH w_dr AS (
SELECT
p_rss_diagnostics.rss_id,
array_agg(DISTINCT t_diagnostics.code) as dr_codes
FROM
w_rss_sae
JOIN pmsi.p_rss_diagnostics ON w_rss_sae.rss_id = p_rss_diagnostics.rss_id AND p_rss_diagnostics.type_diagnostic = 'DR'
JOIN pmsi.t_diagnostics ON t_diagnostics.oid = p_rss_diagnostics.diagnostic_id
GROUP BY p_rss_diagnostics.rss_id
)
UPDATE w_rss_sae SET
dr_codes = w_dr.dr_codes
FROM
w_dr
WHERE
w_rss_sae.rss_id = w_dr.rss_id;
RAISE NOTICE 'Ajout des diagnostcs associes';
WITH w_da AS (
SELECT
p_rss_diagnostics.rss_id,
array_agg(DISTINCT t_diagnostics.code) as da_codes
FROM
w_rss_sae
JOIN pmsi.p_rss_diagnostics ON w_rss_sae.rss_id = p_rss_diagnostics.rss_id AND p_rss_diagnostics.type_diagnostic = 'DA'
JOIN pmsi.t_diagnostics ON t_diagnostics.oid = p_rss_diagnostics.diagnostic_id
GROUP BY p_rss_diagnostics.rss_id
)
UPDATE w_rss_sae SET
da_codes = w_da.da_codes
FROM
w_da
WHERE
w_rss_sae.rss_id = w_da.rss_id;
RAISE NOTICE 'Ajout des actes';
WITH w_actes AS (
SELECT
p_rss_actes.rss_id,
array_agg(DISTINCT t_actes.code) as actes_codes
FROM
w_rss_sae
JOIN pmsi.p_rss_actes ON w_rss_sae.rss_id = p_rss_actes.rss_id
JOIN pmsi.t_actes ON t_actes.oid = p_rss_actes.acte_id
GROUP BY p_rss_actes.rss_id
)
UPDATE w_rss_sae SET
actes_codes = w_actes.actes_codes
FROM
w_actes
WHERE
w_rss_sae.rss_id = w_actes.rss_id;
/************************
* Ecriture des données *
************************/
INSERT INTO pmsi.p_rss_sae (rss_id, import_id, rss_bebe, rss_neuro, rss_mode_hospitalisation_id, rss_discipline_id, rss_dr_codes, rss_da_codes, rss_actes_codes, rss_aut_codes)
SELECT
w_rss_sae.rss_id,
w_rss_sae.import_id,
CASE WHEN w_rss_sae.nb_rum = 1 AND rss_bebe = 1 THEN 1 ELSE 0 END AS rss_bebe,
w_rss_sae.rss_neuro,
CASE
WHEN w_rss_sae.nb_rum_hc >= 1 THEN mh_hc.oid
WHEN w_rss_sae.nb_rum > 0 AND w_rss_sae.nb_rum = w_rss_sae.nb_rum_hm0 + nb_rum_hp THEN mh_hp.oid
ELSE 0 END AS rss_mode_hospitalisation_id,
w_rss_sae.rss_discipline_id,
w_rss_sae.dr_codes as rss_dr_codes,
w_rss_sae.da_codes as rss_da_codes,
w_rss_sae.actes_codes as rss_actes_codes,
w_rss_sae.aut_codes as rss_aut_codes
FROM
w_rss_sae
JOIN pmsi.t_modes_hospitalisation mh_hc ON mh_hc.code = 'HC'
JOIN pmsi.t_modes_hospitalisation mh_hp ON mh_hp.code = 'HP'
ORDER BY w_rss_sae.import_id, w_rss_sae.rss_id;
GET DIAGNOSTICS new_rows = row_count;
RAISE NOTICE '%', format('%s lignes ajoutees', new_rows);
/****************************
* Maintenance de p_rss_sae *
****************************/
RAISE NOTICE 'Maintenance';
DELETE FROM pmsi.p_rss_sae where import_id IS NULL;
PERFORM base.cti_vacuum_forced('pmsi.p_rss_sae');
RETURN 'OK';
END;