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.
 
 

300 lines
6.7 KiB

return: text
lang: plpgsql
src: |
DECLARE
result TEXT;
BEGIN
result = 'OK';
DROP TABLE IF EXISTS w_benchmark;
CREATE TEMP TABLE w_benchmark AS
SELECT
'ETS'::text AS type_ligne,
t_finess.section_id[3] AS region_id,
finess,
mois_sortie AS mois_reference,
'GHM'::text AS type_indicateur,
ghm_id AS parent_id,
ghm5_id,
ARRAY[
sum(CASE WHEN cmd_code <> '28' AND cmd_code <> '15' THEN nb_rsa ELSE 0 END),
sum(nb_rsa),
sum(CASE WHEN cmd_code <> '28' AND cmd_code <> '15' AND duree_sejour > 0 THEN 1 ELSE 0 END),
count(*),
sum(CASE WHEN cmd_code <> '28' AND cmd_code <> '15' AND duree_sejour > 0 THEN nb_rsa ELSE 0 END),
0,
0,
0,
0,
0,
sum(CASE WHEN duree_sejour > 2 AND severite_ghm_code IN ('1','2','3','4') THEN nb_rsa ELSE 0 END),
sum(CASE WHEN cmd_code <> '28' AND cmd_code <> '15' THEN nb_rsa ELSE 0 END),
sum(CASE WHEN cas_code = 'C' THEN nb_rsa ELSE 0 END),
0,
0,
0,
0,
0,
0,
0
]::numeric[] AS ets_ind1,
ARRAY[
sum(CASE WHEN cmd_code <> '28' THEN duree_sejour ELSE 0 END),
sum(nb_rsa*age),
sum(CASE WHEN cmd_code <> '28' AND cmd_code <> '15' AND mode_sortie = '8' AND duree_sejour > 0 THEN nb_rsa ELSE 0 END)*100,
sum(CASE WHEN mode_sortie = '9' THEN nb_rsa ELSE 0 END)*100,
sum(CASE WHEN cmd_code <> '28' AND cmd_code <> '15' AND duree_sejour > 0 THEN duree_sejour ELSE 0 END),
0,
0,
0,
0,
0,
sum(CASE WHEN duree_sejour > 2 AND severite_ghm_code IN ('2','3','4') THEN nb_rsa ELSE 0 END)*100,
sum(CASE WHEN cmd_code <> '28' AND cmd_code <> '15' AND duree_sejour = 0 THEN nb_rsa ELSE 0 END)*100,
sum(CASE WHEN duree_sejour = 0 AND cas_code = 'C' THEN nb_rsa ELSE 0 END)*100,
0,
0,
0,
0,
0,
0,
0
]::numeric[] AS ets_ind2
FROM pmsi.p_rss
JOIN pmsi.t_ghm_c ON p_rss.ghm_id = t_ghm_c.oid
JOIN base.t_finess ON finess = t_finess.code
WHERE date_sortie >= '20150101' AND
etat = '' AND
ghm_id > 0 AND
cmd_code BETWEEN '01' AND '28'
GROUP BY 1,2,3,4,5,6,7;
INSERT INTO w_benchmark
SELECT
type_ligne,
region_id,
finess,
mois_reference,
'GHM5'::text AS type_indicateur,
ghm5_id,
ghm5_id,
ARRAY[
SUM(ets_ind1[01]),
SUM(ets_ind1[02]),
SUM(ets_ind1[03]),
SUM(ets_ind1[04]),
SUM(ets_ind1[05]),
SUM(ets_ind1[06]),
SUM(ets_ind1[07]),
SUM(ets_ind1[08]),
SUM(ets_ind1[09]),
SUM(ets_ind1[10]),
SUM(ets_ind1[11]),
SUM(ets_ind1[12]),
SUM(ets_ind1[13]),
SUM(ets_ind1[14]),
SUM(ets_ind1[15]),
SUM(ets_ind1[16]),
SUM(ets_ind1[17]),
SUM(ets_ind1[18]),
SUM(ets_ind1[19]),
SUM(ets_ind1[20])
]::numeric[] AS ets_ind1,
ARRAY[
SUM(ets_ind2[01]),
SUM(ets_ind2[02]),
SUM(ets_ind2[03]),
SUM(ets_ind2[04]),
SUM(ets_ind2[05]),
SUM(ets_ind2[06]),
SUM(ets_ind2[07]),
SUM(ets_ind2[08]),
SUM(ets_ind2[09]),
SUM(ets_ind2[10]),
SUM(ets_ind2[11]),
SUM(ets_ind2[12]),
SUM(ets_ind2[13]),
SUM(ets_ind2[14]),
SUM(ets_ind2[15]),
SUM(ets_ind2[16]),
SUM(ets_ind2[17]),
SUM(ets_ind2[18]),
SUM(ets_ind2[19]),
SUM(ets_ind2[20])
]::numeric[] AS ets_ind2
FROM w_benchmark
WHERE type_indicateur = 'GHM'
GROUP BY 1,2,3,4,5,6,7
;
-- Total par région
INSERT INTO w_benchmark
SELECT
'REG'::text AS type_ligne,
region_id,
'-1'::text AS finess,
mois_reference,
type_indicateur,
parent_id,
ghm5_id,
ARRAY[
SUM(ets_ind1[01]),
SUM(ets_ind1[02]),
SUM(ets_ind1[03]),
SUM(ets_ind1[04]),
SUM(ets_ind1[05]),
SUM(ets_ind1[06]),
SUM(ets_ind1[07]),
SUM(ets_ind1[08]),
SUM(ets_ind1[09]),
SUM(ets_ind1[10]),
SUM(ets_ind1[11]),
SUM(ets_ind1[12]),
SUM(ets_ind1[13]),
SUM(ets_ind1[14]),
SUM(ets_ind1[15]),
SUM(ets_ind1[16]),
SUM(ets_ind1[17]),
SUM(ets_ind1[18]),
SUM(ets_ind1[19]),
SUM(ets_ind1[20])
]::numeric[] AS ets_ind1,
ARRAY[
SUM(ets_ind2[01]),
SUM(ets_ind2[02]),
SUM(ets_ind2[03]),
SUM(ets_ind2[04]),
SUM(ets_ind2[05]),
SUM(ets_ind2[06]),
SUM(ets_ind2[07]),
SUM(ets_ind2[08]),
SUM(ets_ind2[09]),
SUM(ets_ind2[10]),
SUM(ets_ind2[11]),
SUM(ets_ind2[12]),
SUM(ets_ind2[13]),
SUM(ets_ind2[14]),
SUM(ets_ind2[15]),
SUM(ets_ind2[16]),
SUM(ets_ind2[17]),
SUM(ets_ind2[18]),
SUM(ets_ind2[19]),
SUM(ets_ind2[20])
]::numeric[] AS ets_ind2
FROM w_benchmark
GROUP BY 1,2,3,4,5,6,7
;
-- Total groupe
INSERT INTO w_benchmark
SELECT
'GRP'::text AS type_ligne,
-1::bigint AS region_id,
'-1'::text AS finess,
mois_reference,
type_indicateur,
parent_id,
ghm5_id,
ARRAY[
SUM(ets_ind1[01]),
SUM(ets_ind1[02]),
SUM(ets_ind1[03]),
SUM(ets_ind1[04]),
SUM(ets_ind1[05]),
SUM(ets_ind1[06]),
SUM(ets_ind1[07]),
SUM(ets_ind1[08]),
SUM(ets_ind1[09]),
SUM(ets_ind1[10]),
SUM(ets_ind1[11]),
SUM(ets_ind1[12]),
SUM(ets_ind1[13]),
SUM(ets_ind1[14]),
SUM(ets_ind1[15]),
SUM(ets_ind1[16]),
SUM(ets_ind1[17]),
SUM(ets_ind1[18]),
SUM(ets_ind1[19]),
SUM(ets_ind1[20])
]::numeric[] AS ets_ind1,
ARRAY[
SUM(ets_ind2[01]),
SUM(ets_ind2[02]),
SUM(ets_ind2[03]),
SUM(ets_ind2[04]),
SUM(ets_ind2[05]),
SUM(ets_ind2[06]),
SUM(ets_ind2[07]),
SUM(ets_ind2[08]),
SUM(ets_ind2[09]),
SUM(ets_ind2[10]),
SUM(ets_ind2[11]),
SUM(ets_ind2[12]),
SUM(ets_ind2[13]),
SUM(ets_ind2[14]),
SUM(ets_ind2[15]),
SUM(ets_ind2[16]),
SUM(ets_ind2[17]),
SUM(ets_ind2[18]),
SUM(ets_ind2[19]),
SUM(ets_ind2[20])
]::numeric[] AS ets_ind2
FROM w_benchmark
WHERE type_ligne = 'REG'
GROUP BY 1,2,3,4,5,6,7
;
TRUNCATE pmsi.p_benchmark;
INSERT INTO pmsi.p_benchmark (type_ligne, region_id, finess, parent_id, mois_reference, date_reference, type_indicateur, indicateur_1, indicateur_2)
SELECT type_ligne,
region_id,
finess,
parent_id,
mois_reference,
(mois_reference||'01')::date,
type_indicateur,
ets_ind1,
ets_ind2
FROM w_benchmark
WHERE type_ligne IN ('GRP','REG')
;
INSERT INTO pmsi.p_benchmark (type_ligne, region_id, finess, parent_id, type_indicateur)
SELECT type_ligne,
region_id,
finess,
parent_id,
type_indicateur
FROM w_benchmark
WHERE type_ligne IN ('ETS')
GROUP BY 1,2,3,4,5
;
ANALYSE pmsi.p_benchmark
;
RETURN result;
END;