return: text
|
|
lang: plpgsql
|
|
src: |
|
|
DECLARE
|
|
ref REFCURSOR;
|
|
seq TEXT;
|
|
sequence_gm TEXT := '';
|
|
request TEXT := '';
|
|
resultat TEXT := '';
|
|
case_cmd TEXT := '';
|
|
gm_classe_code TEXT := 'CTI_GM_MSAP_2015';
|
|
|
|
BEGIN
|
|
RAISE NOTICE '%' , 'Check si pmsi.p_rss_gm existe';
|
|
-- Vérifie l'existance de la table pmsi.p_rss_gm
|
|
IF NOT EXISTS (SELECT table_name FROM information_schema.tables WHERE table_name = 'p_rss_gm' AND table_schema = 'pmsi') THEN
|
|
RAISE NOTICE '%' , 'Création de la table pmsi.p_rss_gm';
|
|
CREATE TABLE pmsi.p_rss_gm (finess text, rss_id bigint, gm_principal_id bigint);
|
|
CREATE INDEX i_rss_gm_1 ON pmsi.p_rss_gm USING btree (rss_id);
|
|
END IF;
|
|
|
|
-- Présélection des RSS à traiter :
|
|
-- RSS post 2011 avec au moins un acte faisant partie des gestes marqueurs
|
|
|
|
RAISE NOTICE '%' , 'Preselection des donnees';
|
|
|
|
DROP TABLE IF EXISTS w_actes_c;
|
|
CREATE TEMP TABLE w_actes_c AS
|
|
SELECT *
|
|
FROM pmsi.t_actes_c
|
|
WHERE section_id[12] > 0
|
|
;
|
|
|
|
ANALYSE w_actes_c
|
|
;
|
|
|
|
CREATE INDEX w_actes_c_i1 ON w_actes_c USING btree (oid);
|
|
|
|
DROP TABLE IF EXISTS w_rss_actes;
|
|
CREATE TEMP TABLE w_rss_actes (
|
|
finess text,
|
|
rss_id bigint,
|
|
acte_id bigint,
|
|
acte_code text,
|
|
icr numeric,
|
|
gm_2015_id bigint,
|
|
gm_2015_code text,
|
|
nb_gm_2015 bigint,
|
|
nombre bigint);
|
|
INSERT INTO w_rss_actes
|
|
SELECT
|
|
p_rss.finess,
|
|
p_rss_actes.rss_id,
|
|
p_rss_actes.acte_id,
|
|
w_actes_c.code AS acte_code,
|
|
w_actes_c.icr_1 AS icr,
|
|
w_actes_c.section_id[12] as gm_2015_id,
|
|
w_actes_c.section_code[12] as gm_2015_code,
|
|
0 as nb_gm_2015,
|
|
sum(p_rss_actes.nombre) as nombre
|
|
FROM
|
|
pmsi.p_rss_actes
|
|
JOIN w_actes_c ON p_rss_actes.acte_id = w_actes_c.oid
|
|
JOIN pmsi.p_rss ON p_rss.oid = p_rss_actes.rss_id
|
|
WHERE 1=1
|
|
AND p_rss.date_sortie >= (date_trunc('year', now()) - interval '2 year')::date
|
|
AND p_rss_actes.activite_ccam = '1'
|
|
--and no_rss = 246789
|
|
GROUP BY 1,2,3,4,5,6,7,8
|
|
ORDER BY 1,2,4;
|
|
|
|
ANALYSE w_rss_actes
|
|
;
|
|
|
|
CREATE INDEX w_rss_actes_i1 ON w_rss_actes USING btree (rss_id);
|
|
|
|
-- Acte spécial BELB001
|
|
DROP TABLE IF EXISTS w_rss_actes_belb001;
|
|
CREATE TEMP TABLE w_rss_actes_belb001 AS
|
|
SELECT rss_id
|
|
FROM pmsi.v_rss_actes_3
|
|
WHERE acte_code = 'BELB001'
|
|
GROUP BY 1
|
|
;
|
|
|
|
ANALYSE w_rss_actes_belb001
|
|
;
|
|
|
|
CREATE INDEX w_rss_actes_belb001_i1 ON w_rss_actes_belb001 USING btree (rss_id);
|
|
|
|
|
|
-- Récupère le numéros de séquence de la classe des gestes marqueurs principaux
|
|
|
|
request := 'SELECT sequence FROM pmsi.t_classes WHERE t_classes.code = ''' || gm_classe_code || ''' AND t_classes.is_cti = ''1'';';
|
|
OPEN ref FOR
|
|
EXECUTE request;
|
|
-- Construction de la requête qui fait un case when géant sur tous les gestes marqueurs
|
|
-- On ne tient pas compte des conditons liées aux gestes marqueurs isolés (conditions sur le champ 'condition_gm_ok')
|
|
LOOP
|
|
FETCH ref INTO seq;
|
|
IF NOT FOUND THEN EXIT; END IF;
|
|
sequence_gm = seq;
|
|
request := '
|
|
SELECT base.cti_group_concat_without_sep(case_when)
|
|
FROM
|
|
(
|
|
SELECT '' CASE'' AS case_when
|
|
|
|
UNION
|
|
|
|
(
|
|
SELECT
|
|
'' WHEN gm_2015_id = '' ||
|
|
t_classes_sections.oid ||
|
|
CASE WHEN t_classes_sections.condition <> '''' AND strpos(t_classes_sections.condition, ''condition_gm_ok'') = 0 THEN '' AND '' ||
|
|
t_classes_sections.condition ELSE '''' END ||
|
|
'' THEN 1 ''
|
|
FROM pmsi.t_classes, pmsi.t_classes_sections, pmsi.t_listes_tables
|
|
WHERE
|
|
t_classes_sections.classe_id = t_classes.oid
|
|
AND t_classes.table_id = t_listes_tables.oid
|
|
AND t_listes_tables.code = ''ACTE''
|
|
AND t_classes.sequence = ' || seq || '::numeric
|
|
ORDER BY t_classes_sections.oid
|
|
)
|
|
UNION
|
|
|
|
SELECT ''ELSE 0 END''
|
|
|
|
ORDER BY 1
|
|
) subview';
|
|
FOR resultat IN EXECUTE(request) LOOP
|
|
--RAISE NOTICE 'Resultat : %', resultat;
|
|
case_cmd := resultat;
|
|
END LOOP;
|
|
END LOOP;
|
|
CLOSE ref;
|
|
-- Création d'une table d'actes avec les gestes marqueurs conditionnés
|
|
RAISE NOTICE '%' , 'Estampillage des gestes marqueurs (avec condition) sur les RSS';
|
|
|
|
DROP TABLE IF EXISTS w_actes;
|
|
request := '
|
|
CREATE TEMP TABLE w_actes AS
|
|
SELECT
|
|
v_rss_actes_1.finess,
|
|
v_rss_actes_1.rss_id,
|
|
v_rss_actes_1.acte_id AS acte_id,
|
|
v_rss_actes_1.acte_code AS acte_code,
|
|
v_rss_actes_1.icr AS icr,
|
|
CASE WHEN ' || case_cmd || ' = 1 THEN gm_2015_id ELSE 0 END AS acte_section_id
|
|
FROM
|
|
w_rss_actes v_rss_actes_1
|
|
JOIN pmsi.v_rss_12 v_rss_1 ON v_rss_1.rss_id = v_rss_actes_1.rss_id
|
|
ORDER BY 1, 2, 3 DESC
|
|
';
|
|
-- RAISE NOTICE 'Request : %', request;
|
|
EXECUTE (request);
|
|
|
|
ANALYSE w_actes
|
|
;
|
|
CREATE INDEX w_actes_i1 ON w_actes USING btree (rss_id)
|
|
;
|
|
CREATE INDEX w_actes_i2 ON w_actes USING btree (acte_id)
|
|
;
|
|
|
|
-----------------------------------------------------
|
|
|
|
RAISE NOTICE '%' , 'Traitement des gestes isoles _ 1ere partie';
|
|
-- Comptage des gestes marqueurs différents par RSS
|
|
DROP TABLE IF EXISTS w_count;
|
|
CREATE TEMP TABLE w_count AS
|
|
SELECT
|
|
finess, rss_id, count(distinct gm_2015_id) as nb_2015
|
|
FROM w_rss_actes
|
|
GROUP BY 1, 2;
|
|
---------------------------------------------------
|
|
-- Mise à jour du nombre de GM différents dans la table de travail
|
|
UPDATE w_rss_actes SET
|
|
nb_gm_2015 = nb_2015
|
|
FROM
|
|
w_count
|
|
WHERE
|
|
w_count.rss_id = w_rss_actes.rss_id
|
|
AND w_count.finess = w_rss_actes.finess;
|
|
DROP TABLE IF EXISTS w_count;
|
|
---------------------------------------------------------------------
|
|
-- GESTES ISOLES
|
|
---------------------------------------------------------------------
|
|
-- 1ere partie : Séjour comprenant un ou plusieurs actes du même geste marqueur non associés à un acte d’un autre geste marqueur
|
|
DROP TABLE IF EXISTS w_rss_gm_isoles;
|
|
CREATE TEMP TABLE w_rss_gm_isoles(finess text, rss_id bigint, gm_2015_id bigint);
|
|
-- NFFC002 sur le geste marqueur GM06 doit être un geste isolé
|
|
INSERT INTO w_rss_gm_isoles
|
|
SELECT
|
|
finess,
|
|
rss_id,
|
|
gm_2015_id
|
|
FROM
|
|
w_rss_actes
|
|
WHERE 1=1
|
|
AND nb_gm_2015 > 1
|
|
AND gm_2015_code = 'GM06'
|
|
AND acte_code ='NFFC002'
|
|
GROUP BY 1,2,3;
|
|
-- MHFA001 sur le geste marqueur GM10 doit être un geste isolé
|
|
INSERT INTO w_rss_gm_isoles
|
|
SELECT
|
|
finess,
|
|
rss_id,
|
|
gm_2015_id
|
|
FROM
|
|
w_rss_actes
|
|
WHERE 1=1
|
|
AND nb_gm_2015 > 1
|
|
AND gm_2015_code = 'GM10'
|
|
AND acte_code ='MHFA001'
|
|
GROUP BY 1,2,3;
|
|
-- le geste marqueur GM19 doit être un geste isolé
|
|
INSERT INTO w_rss_gm_isoles
|
|
SELECT
|
|
finess,
|
|
rss_id,
|
|
gm_2015_id
|
|
FROM
|
|
w_rss_actes
|
|
WHERE 1=1
|
|
AND nb_gm_2015 > 1
|
|
AND gm_2015_code = 'GM19'
|
|
GROUP BY 1,2,3;
|
|
-- MGCC001 sur le geste marqueur GM30 doit être un geste isolé
|
|
INSERT INTO w_rss_gm_isoles
|
|
SELECT
|
|
finess,
|
|
rss_id,
|
|
gm_2015_id
|
|
FROM
|
|
w_rss_actes
|
|
WHERE 1=1
|
|
AND nb_gm_2015 > 1
|
|
AND gm_2015_code = 'GM30'
|
|
AND acte_code = 'MGCC001'
|
|
GROUP BY 1,2,3;
|
|
-- le geste marqueur GM39 doit être un geste isolé
|
|
INSERT INTO w_rss_gm_isoles
|
|
SELECT
|
|
finess,
|
|
rss_id,
|
|
gm_2015_id
|
|
FROM
|
|
w_rss_actes
|
|
WHERE 1=1
|
|
AND nb_gm_2015 > 1
|
|
AND gm_2015_code = 'GM39'
|
|
GROUP BY 1,2,3;
|
|
-- HASA013 sur le geste marqueur GM41 doit être un geste isolé
|
|
INSERT INTO w_rss_gm_isoles
|
|
SELECT
|
|
finess,
|
|
rss_id,
|
|
gm_2015_id
|
|
FROM
|
|
w_rss_actes
|
|
WHERE 1=1
|
|
AND nb_gm_2015 > 1
|
|
AND gm_2015_code = 'GM41'
|
|
AND acte_code = 'HASA013'
|
|
GROUP BY 1,2,3;
|
|
-- JCAE001 et JCKE002 sur le geste marqueur GM46 doivent être un geste isolé
|
|
INSERT INTO w_rss_gm_isoles
|
|
SELECT
|
|
finess,
|
|
rss_id,
|
|
gm_2015_id
|
|
FROM
|
|
w_rss_actes
|
|
WHERE 1=1
|
|
AND nb_gm_2015 > 1
|
|
AND gm_2015_code = 'GM46'
|
|
AND acte_code = 'JCAE001'
|
|
GROUP BY 1,2,3;
|
|
INSERT INTO w_rss_gm_isoles
|
|
SELECT
|
|
finess,
|
|
rss_id,
|
|
gm_2015_id
|
|
FROM
|
|
w_rss_actes
|
|
WHERE 1=1
|
|
AND nb_gm_2015 > 1
|
|
AND gm_2015_code = 'GM46'
|
|
AND acte_code = 'JCKE002'
|
|
GROUP BY 1,2,3;
|
|
-- le geste marqueur GM26 doit être un geste isolé sauf associé à un BELB001
|
|
INSERT INTO w_rss_gm_isoles
|
|
SELECT
|
|
w_rss_actes.finess,
|
|
w_rss_actes.rss_id,
|
|
w_rss_actes.gm_2015_id
|
|
FROM
|
|
w_rss_actes
|
|
LEFT JOIN w_rss_actes_belb001 ON w_rss_actes.rss_id = w_rss_actes_belb001.rss_id
|
|
WHERE 1=1
|
|
AND nb_gm_2015 > 1
|
|
AND gm_2015_code = 'GM26'
|
|
AND w_rss_actes_belb001 IS NULL
|
|
GROUP BY 1,2,3;
|
|
-- le geste marqueur GM13 doivent être des gestes isolés et rélisés de manière unilatérale
|
|
-- ce dernier critère peut s'exprimer par un nombre d'activite 1 pour cet acte = 1
|
|
INSERT INTO w_rss_gm_isoles
|
|
SELECT
|
|
finess,
|
|
rss_id,
|
|
gm_2015_id
|
|
FROM
|
|
w_rss_actes
|
|
WHERE 1=1
|
|
AND nb_gm_2015 > 1
|
|
AND gm_2015_code = 'GM13'
|
|
AND nombre > 1
|
|
GROUP BY 1,2,3;
|
|
-- idem pour GM 19
|
|
INSERT INTO w_rss_gm_isoles
|
|
SELECT
|
|
finess,
|
|
rss_id,
|
|
gm_2015_id
|
|
FROM
|
|
w_rss_actes
|
|
WHERE 1=1
|
|
AND nb_gm_2015 > 1
|
|
AND gm_2015_code = 'GM19'
|
|
AND nombre > 1
|
|
GROUP BY 1,2,3;
|
|
-- idem pour GM 29
|
|
INSERT INTO w_rss_gm_isoles
|
|
SELECT
|
|
finess,
|
|
rss_id,
|
|
gm_2015_id
|
|
FROM
|
|
w_rss_actes
|
|
WHERE 1=1
|
|
AND nb_gm_2015 > 1
|
|
AND gm_2015_code = 'GM29'
|
|
AND nombre > 1
|
|
GROUP BY 1,2,3;
|
|
-- hors associtation avec GM26 pour GM 27, 54 et 55
|
|
INSERT INTO w_rss_gm_isoles
|
|
SELECT
|
|
finess,
|
|
rss_id,
|
|
gm_2015_id
|
|
FROM
|
|
w_rss_actes
|
|
WHERE 1=1
|
|
AND gm_2015_code IN ('GM27','GM54','GM55')
|
|
AND rss_id != ALL(Array(SELECT DISTINCT rss_id FROM w_rss_actes WHERE gm_2015_code = 'GM26')::bigint[])
|
|
GROUP BY 1,2,3;
|
|
|
|
-- Suppression des RSS qui ont plusieurs gestes marqueurs (ou plusieurs actes ou une mauvaise association) et dont la condition stipule un geste isolé (ou unilateral ou une bonne association associé)
|
|
|
|
/*
|
|
DELETE FROM w_rss_actes
|
|
USING w_rss_gm_isoles
|
|
WHERE 1=1
|
|
AND w_rss_actes.rss_id = w_rss_gm_isoles.rss_id
|
|
AND w_rss_actes.gm_2015_id = w_rss_gm_isoles.gm_2015_id;
|
|
*/
|
|
|
|
DELETE FROM w_actes
|
|
USING w_rss_gm_isoles
|
|
WHERE 1=1
|
|
AND w_actes.finess = w_rss_gm_isoles.finess
|
|
AND w_actes.rss_id = w_rss_gm_isoles.rss_id
|
|
AND w_actes.acte_section_id = w_rss_gm_isoles.gm_2015_id;
|
|
DROP TABLE IF EXISTS w_rss_gm_isoles;
|
|
-- 2eme partie : Séjours comprenant un ou plusieurs actes du même geste marqueur non associés à un acte de la liste fermée des «actes classant opératoires »
|
|
RAISE NOTICE '%' , 'Traitement des gestes isoles _ 2eme partie';
|
|
|
|
-- Liste des RSS qui n'ont qu'un geste marqueur faisant partie de la liste des gestes marqueurs devant être isolés
|
|
DROP TABLE IF EXISTS w_geste_isole;
|
|
CREATE TEMP TABLE w_geste_isole AS
|
|
SELECT
|
|
w_rss_actes.finess,
|
|
w_rss_actes.rss_id,
|
|
w_rss_actes.gm_2015_id,
|
|
w_rss_actes.gm_2015_code
|
|
FROM
|
|
w_rss_actes
|
|
LEFT JOIN w_rss_actes_belb001 ON w_rss_actes.rss_id = w_rss_actes_belb001.rss_id
|
|
WHERE 1=1
|
|
AND nb_gm_2015 = 1
|
|
AND
|
|
(
|
|
(gm_2015_code = 'GM06' and acte_code = 'NFFC002') OR
|
|
(gm_2015_code = 'GM10' and acte_code = 'MHFA001') OR
|
|
(gm_2015_code = 'GM13') OR
|
|
(gm_2015_code = 'GM19') OR
|
|
(gm_2015_code = 'GM26' AND w_rss_actes_belb001 IS NULL) OR
|
|
(gm_2015_code = 'GM29') OR
|
|
(gm_2015_code = 'GM30' and acte_code = 'MGCC001') OR
|
|
(gm_2015_code = 'GM39') OR
|
|
(gm_2015_code = 'GM41' and acte_code = 'HASA013') OR
|
|
(gm_2015_code = 'GM46' and acte_code = 'JCAE001') OR
|
|
(gm_2015_code = 'GM46' and acte_code = 'JCKE002')
|
|
)
|
|
GROUP BY 1, 2, 3, 4;
|
|
|
|
ANALYSE w_geste_isole
|
|
;
|
|
|
|
CREATE INDEX w_geste_isole_i1 ON w_geste_isole USING btree (rss_id);
|
|
|
|
|
|
-- Liste des RSS (avec leurs actes) avec un seul geste marqueur faisant partie de la liste des gestes marqueurs devant être isolés
|
|
-- et avec au moins un acte ne faisant pas partie des actes du geste marqueur
|
|
DROP TABLE IF EXISTS w_liste_actes;
|
|
CREATE TEMP TABLE w_liste_actes (finess text, rss_id bigint, gm_2015_id bigint, gm_2015_code text, liste_actes text[]);
|
|
INSERT INTO w_liste_actes
|
|
SELECT
|
|
v_rss_actes_3.finess,
|
|
v_rss_actes_3.rss_id,
|
|
w_geste_isole.gm_2015_id,
|
|
w_geste_isole.gm_2015_code,
|
|
base.cti_array_accum(v_rss_actes_3.acte_code::text) as liste_actes
|
|
FROM
|
|
pmsi.v_rss_actes_3
|
|
JOIN w_geste_isole using (rss_id)
|
|
WHERE 1=1
|
|
AND (
|
|
(w_geste_isole.gm_2015_code = 'GM06' AND v_rss_actes_3.acte_section_code[12] <> 'GM06') OR
|
|
(w_geste_isole.gm_2015_code = 'GM10' AND v_rss_actes_3.acte_section_code[12] <> 'GM10') OR
|
|
(w_geste_isole.gm_2015_code = 'GM13' AND v_rss_actes_3.acte_section_code[12] <> 'GM13') OR
|
|
(w_geste_isole.gm_2015_code = 'GM19' AND v_rss_actes_3.acte_section_code[12] <> 'GM19') OR
|
|
(w_geste_isole.gm_2015_code = 'GM26' AND v_rss_actes_3.acte_section_code[12] <> 'GM26') OR
|
|
(w_geste_isole.gm_2015_code = 'GM29' AND v_rss_actes_3.acte_section_code[12] <> 'GM29') OR
|
|
(w_geste_isole.gm_2015_code = 'GM30' AND v_rss_actes_3.acte_section_code[12] <> 'GM30') OR
|
|
(w_geste_isole.gm_2015_code = 'GM39' AND v_rss_actes_3.acte_section_code[12] <> 'GM39') OR
|
|
(w_geste_isole.gm_2015_code = 'GM41' AND v_rss_actes_3.acte_section_code[12] <> 'GM41') OR
|
|
(w_geste_isole.gm_2015_code = 'GM46' AND v_rss_actes_3.acte_section_code[12] <> 'GM46')
|
|
)
|
|
GROUP BY 1, 2, 3, 4;
|
|
|
|
DROP TABLE IF EXISTS w_geste_isole;
|
|
-- Suppression des gestes marqueurs pour les séjours qui ont un acte ne faisant pas partie du geste marqueur et faisant partie de la liste des actes opératoires classants
|
|
|
|
DELETE FROM w_actes
|
|
USING w_liste_actes
|
|
WHERE 1=1
|
|
AND w_actes.finess = w_liste_actes.finess
|
|
AND w_actes.rss_id = w_liste_actes.rss_id
|
|
AND w_actes.acte_section_id = w_liste_actes.gm_2015_id
|
|
AND w_liste_actes.liste_actes && (select array(SELECT t_actes.code FROM pmsi.t_listes_contenu JOIN pmsi.t_listes ON t_listes.oid = t_listes_contenu.liste_id JOIN pmsi.t_actes on t_actes.oid = t_listes_contenu.to_id WHERE t_listes.code = 'CTI_AOP_11F'))::text[];
|
|
|
|
DROP TABLE IF EXISTS w_liste_actes;
|
|
|
|
|
|
|
|
-- Affectation d'un geste marqueur principal au RSS. Si plusieurs gestes marqueurs sur le RSS, le geste marqueur principal est celui de l'acte avec le plus fort ICR
|
|
|
|
RAISE NOTICE '%' , 'Peuplement de la table p_rss_gm';
|
|
|
|
TRUNCATE pmsi.p_rss_gm;
|
|
|
|
EXECUTE
|
|
'INSERT INTO pmsi.p_rss_gm
|
|
(
|
|
finess,
|
|
rss_id,
|
|
gm_principal_id
|
|
)
|
|
(
|
|
SELECT
|
|
finess,
|
|
rss_id,
|
|
(max(array[icr, acte_section_id]))[2] AS gm_principal_id
|
|
FROM w_actes
|
|
WHERE w_actes.acte_section_id > 0
|
|
GROUP BY 1,2
|
|
ORDER BY 1,2
|
|
)'
|
|
;
|
|
|
|
-- Mise à jour des Flags gm_condition_ok pour les actes qui doivent être des gestes isolés
|
|
RAISE NOTICE '%' , 'Flag actes';
|
|
UPDATE pmsi.p_rss_actes
|
|
SET condition_gm_ok = '1'
|
|
FROM
|
|
w_actes
|
|
WHERE 1=1
|
|
AND p_rss_actes.rss_id = w_actes.rss_id
|
|
AND p_rss_actes.finess = w_actes.finess
|
|
AND p_rss_actes.acte_id = w_actes.acte_id
|
|
AND w_actes.acte_code = any(array['NFFC002', 'MHFA001', 'NDPA004', 'NDPA009', 'NHMA002', 'LMMA006', 'LMMA009','LMMC020', 'BFEA001','BFGA001','BFGA002','BFGA003','BFGA004','BFGA427','BFGA005','BFGA006','BFGA007','BFGA008','BFGA009','BFGA010','BFKA001','BFLA001','BFLA002','BFLA003','BFLA004','MGCC001','NDGA003','NJPA007','NDFA002','NGFA002','HAFA021','HAFA034','HASA013','JCAE001','JCKE002'])
|
|
AND COALESCE(condition_gm_ok,'') <> '1'
|
|
;
|
|
DROP TABLE IF EXISTS w_actes;
|
|
RETURN 'OK';
|
|
END;
|