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.
 
 

850 lines
37 KiB

return: text
lang: plpgsql
parameters:
p0:
type: bigint
name: i_enquete_id
p1:
type: bigint
name: i_fiche5_rss_id
src: |
DECLARE
result TEXT;
fg_dir TEXT;
fg_exe TEXT;
BEGIN
UPDATE pmsi.p_fiche5_rss SET
scenar1_rum_um_code = CASE WHEN scenar1_rule = '' OR scenar1_rule = 'OKAM' OR scenar1_rum_um_code IS NULL THEN initial_rum_um_code ELSE scenar1_rum_um_code END,
scenar1_rum_dp_code = CASE WHEN scenar1_rule = '' OR scenar1_rule = 'OKAM' OR scenar1_rum_dp_code IS NULL THEN initial_rum_dp_code ELSE scenar1_rum_dp_code END,
scenar1_rum_dr_code = CASE WHEN scenar1_rule = '' OR scenar1_rule = 'OKAM' OR scenar1_rum_dr_code IS NULL THEN initial_rum_dr_code ELSE scenar1_rum_dr_code END,
scenar1_rum_da_code = CASE WHEN scenar1_rule = '' OR scenar1_rule = 'OKAM' OR scenar1_rum_da_code IS NULL THEN initial_rum_da_code ELSE scenar1_rum_da_code END,
scenar1_rum_ccam_code = CASE WHEN scenar1_rule = '' OR scenar1_rule = 'OKAM' OR scenar1_rum_ccam_code IS NULL THEN initial_rum_ccam_code ELSE scenar1_rum_ccam_code END,
scenar2_rum_um_code = CASE WHEN scenar2_rule = '' OR scenar2_rule = 'OKAM' OR scenar2_rum_um_code IS NULL THEN initial_rum_um_code ELSE scenar2_rum_um_code END,
scenar2_rum_dp_code = CASE WHEN scenar2_rule = '' OR scenar2_rule = 'OKAM' OR scenar2_rum_dp_code IS NULL THEN initial_rum_dp_code ELSE scenar2_rum_dp_code END,
scenar2_rum_dr_code = CASE WHEN scenar2_rule = '' OR scenar2_rule = 'OKAM' OR scenar2_rum_dr_code IS NULL THEN initial_rum_dr_code ELSE scenar2_rum_dr_code END,
scenar2_rum_da_code = CASE WHEN scenar2_rule = '' OR scenar2_rule = 'OKAM' OR scenar2_rum_da_code IS NULL THEN initial_rum_da_code ELSE scenar2_rum_da_code END,
scenar2_rum_ccam_code = CASE WHEN scenar2_rule = '' OR scenar2_rule = 'OKAM' OR scenar2_rum_ccam_code IS NULL THEN initial_rum_ccam_code ELSE scenar2_rum_ccam_code END,
control_rum_um_code = CASE WHEN control_rule = '' OR control_rule = 'OKAM' OR control_rum_um_code IS NULL THEN initial_rum_um_code ELSE control_rum_um_code END,
control_rum_dp_code = CASE WHEN control_rule = '' OR control_rule = 'OKAM' OR control_rum_dp_code IS NULL THEN initial_rum_dp_code ELSE control_rum_dp_code END,
control_rum_dr_code = CASE WHEN control_rule = '' OR control_rule = 'OKAM' OR control_rum_dr_code IS NULL THEN initial_rum_dr_code ELSE control_rum_dr_code END,
control_rum_da_code = CASE WHEN control_rule = '' OR control_rule = 'OKAM' OR control_rum_da_code IS NULL THEN initial_rum_da_code ELSE control_rum_da_code END,
control_rum_ccam_code = CASE WHEN control_rule = '' OR control_rule = 'OKAM' OR control_rum_ccam_code IS NULL THEN initial_rum_ccam_code ELSE control_rum_ccam_code END,
retenu_rum_um_code = CASE WHEN retenu_rule = '' OR retenu_rule = 'OKAM' OR retenu_rum_um_code IS NULL THEN initial_rum_um_code ELSE retenu_rum_um_code END,
retenu_rum_dp_code = CASE WHEN retenu_rule = '' OR retenu_rule = 'OKAM' OR retenu_rum_dp_code IS NULL THEN initial_rum_dp_code ELSE retenu_rum_dp_code END,
retenu_rum_dr_code = CASE WHEN retenu_rule = '' OR retenu_rule = 'OKAM' OR retenu_rum_dr_code IS NULL THEN initial_rum_dr_code ELSE retenu_rum_dr_code END,
retenu_rum_da_code = CASE WHEN retenu_rule = '' OR retenu_rule = 'OKAM' OR retenu_rum_da_code IS NULL THEN initial_rum_da_code ELSE retenu_rum_da_code END,
retenu_rum_ccam_code = CASE WHEN retenu_rule = '' OR retenu_rule = 'OKAM' OR retenu_rum_ccam_code IS NULL THEN initial_rum_ccam_code ELSE retenu_rum_ccam_code END
;
DROP TABLE IF EXISTS w_fiche5_rss;
CREATE TEMP TABLE w_fiche5_rss AS
SELECT *
FROM pmsi.p_fiche5_rss
WHERE (
p_fiche5_rss.enquete_id = i_enquete_id OR
p_fiche5_rss.oid = i_fiche5_rss_id
)
;
fg_dir = (SELECT MAX(t_fiche5_enquete.fg_dir) FROM pmsi.t_fiche5_enquete WHERE t_fiche5_enquete.oid IN (SELECT enquete_id FROM w_fiche5_rss))
;
fg_exe = 'fg1718';
IF fg_dir LIKE '%2017' THEN
fg_exe = 'fg1617';
END IF;
IF fg_dir LIKE '%2019' THEN
fg_exe = 'fg1819';
END IF;
-- UM
EXECUTE
'COPY
(
SELECT initial_um_in[i]
FROM pmsi.t_fiche5_enquete
JOIN generate_series(1,500) AS i ON initial_um_in[i] <> ''''
WHERE t_fiche5_enquete.oid IN (SELECT enquete_id FROM w_fiche5_rss)
)
TO '''||fg_dir||'/files/FICHE5_GRP.FICUM''
'
;
-- RUM à grouper
DROP TABLE IF EXISTS w_fiche5_IN;
CREATE TEMP TABLE w_fiche5_IN AS
SELECT p_fiche5_rss.oid AS fiche5_rss_id,
'I' AS scenario, i,
'GHS'::text AS rule,
substr(initial_rum_in[i],16,9) || '0' || substr(initial_rum_in[i],11,2) || to_char(p_fiche5_rss.oid,'FM0000000000')||'0000000010' || substr(initial_rum_in[i],48) AS data,
initial_rum_um_code[i] AS um,
initial_rum_dp_code[i] AS dp,
initial_rum_dr_code[i] AS dr,
initial_rum_da_code[i] AS da,
initial_rum_ccam_code[i] AS ccam,
''::text AS ccam_new
FROM w_fiche5_rss p_fiche5_rss
JOIN generate_series (1 , 10) AS i ON initial_rum_in[i] <> ''
UNION
SELECT p_fiche5_rss.oid AS fiche5_rss_id,
'1' AS scenario, i,
scenar1_rule AS rule,
substr(initial_rum_in[i],16,9) || '0' || substr(initial_rum_in[i],11,2) || to_char(p_fiche5_rss.oid,'FM0000000000')||'0000000011' || substr(initial_rum_in[i],48) AS data,
scenar1_rum_um_code[i] AS um,
scenar1_rum_dp_code[i] AS dp,
scenar1_rum_dr_code[i] AS dr,
scenar1_rum_da_code[i] AS da,
scenar1_rum_ccam_code[i] AS ccam,
''::text AS ccam_new
FROM w_fiche5_rss p_fiche5_rss
JOIN generate_series (1 , 10) AS i ON initial_rum_in[i] <> ''
UNION
SELECT p_fiche5_rss.oid AS fiche5_rss_id,
'2' AS scenario, i,
scenar2_rule AS rule,
substr(initial_rum_in[i],16,9) || '0' || substr(initial_rum_in[i],11,2) || to_char(p_fiche5_rss.oid,'FM0000000000')||'0000000012' || substr(initial_rum_in[i],48) AS data,
scenar2_rum_um_code[i] AS um,
scenar2_rum_dp_code[i] AS dp,
scenar2_rum_dr_code[i] AS dr,
scenar2_rum_da_code[i] AS da,
scenar2_rum_ccam_code[i] AS ccam,
''::text AS ccam_new
FROM w_fiche5_rss p_fiche5_rss
JOIN generate_series (1 , 10) AS i ON initial_rum_in[i] <> ''
UNION
SELECT p_fiche5_rss.oid AS fiche5_rss_id,
'C' AS scenario, i,
control_rule AS rule,
substr(initial_rum_in[i],16,9) || '0' || substr(initial_rum_in[i],11,2) || to_char(p_fiche5_rss.oid,'FM0000000000')||'0000000015' || substr(initial_rum_in[i],48) AS data,
control_rum_um_code[i] AS um,
control_rum_dp_code[i] AS dp,
control_rum_dr_code[i] AS dr,
control_rum_da_code[i] AS da,
control_rum_ccam_code[i] AS ccam,
''::text AS ccam_new
FROM w_fiche5_rss p_fiche5_rss
JOIN generate_series (1 , 10) AS i ON initial_rum_in[i] <> ''
UNION
SELECT p_fiche5_rss.oid AS fiche5_rss_id,
'R' AS scenario, i,
retenu_rule AS rule,
substr(initial_rum_in[i],16,9) || '0' || substr(initial_rum_in[i],11,2) || to_char(p_fiche5_rss.oid,'FM0000000000')||'0000000019' || substr(initial_rum_in[i],48) AS data,
retenu_rum_um_code[i] AS um,
retenu_rum_dp_code[i] AS dp,
retenu_rum_dr_code[i] AS dr,
retenu_rum_da_code[i] AS da,
retenu_rum_ccam_code[i] AS ccam,
''::text AS ccam_new
FROM w_fiche5_rss p_fiche5_rss
JOIN generate_series (1 , 10) AS i ON initial_rum_in[i] <> ''
;
UPDATE w_fiche5_IN
SET data = overlay(data placing rpad(um, 4, ' ') from 72 for 4)
;
UPDATE w_fiche5_IN
SET data = overlay(data placing rpad(dp, 8, ' ') from 126 for 8)
;
UPDATE w_fiche5_IN
SET data = overlay(data placing rpad(dr, 8, ' ') from 134 for 8)
;
-- Remplacement DA
UPDATE w_fiche5_IN
SET da = subview.da
FROM
(
SELECT fiche5_rss_id, scenario, i, array_to_string(base.cti_array_accum(rpad(trim((string_to_array(da,','))[dai]),8,' ')),'') AS da
FROM w_fiche5_IN
JOIN generate_series(1,100) AS dai ON trim((string_to_array(da,','))[dai]) <> ''
GROUP BY 1,2,3
ORDER BY 1,2,3
) subview
WHERE w_fiche5_IN.scenario = subview.scenario AND
w_fiche5_IN.fiche5_rss_id = subview.fiche5_rss_id AND
w_fiche5_IN.i = subview.i
;
UPDATE w_fiche5_IN
SET data = overlay(data placing rpad(dr, 8, ' ') from 134 for 8)
;
UPDATE w_fiche5_IN
SET data = overlay(
overlay(
data
placing
da
from 178 for (base.Cti_to_number(substr(data,119,2))::integer*8+base.Cti_to_number(substr(data,121,2))::integer*8)
)
placing
to_char(length(da)/8, 'FM00') || '00'
from 119 for 4
)
WHERE w_fiche5_IN.scenario <> 'I'
;
-- Remplacement CCAM
UPDATE w_fiche5_IN
SET ccam_new = subview.ccam
FROM
(
SELECT fiche5_rss_id, scenario, i, array_to_string(base.cti_array_accum(buff_acte),'') AS ccam
FROM
(
SELECT fiche5_rss_id, scenario, i, buff_acte AS buff_acte
FROM
(
SELECT
fiche5_rss_id, scenario, i, substr(buff_actes,((c-1)*29)+1,29) AS buff_acte, ccam
FROM
(
SELECT fiche5_rss_id, scenario, i, ccam, base.cti_to_number(substr(data,123,3))::integer AS nb_actes,
substr(data,
178+
base.cti_to_number(substr(data,119,2))::integer*8+
base.cti_to_number(substr(data,121,2))::integer*8) AS buff_actes
FROM w_fiche5_IN
) subview
JOIN generate_series(1,nb_actes) c ON 1=1
) subview
WHERE ccam ILIKE '%'||substr(buff_acte,9,7)||'%'
UNION
SELECT fiche5_rss_id, scenario, i,
rpad(
substr(data,78,8)||
rpad(trim((string_to_array(ccam,','))[ccami]),7,' ')||
' 01 0001'
,29,' ')
FROM w_fiche5_IN
JOIN generate_series(1,100) AS ccami ON
trim((string_to_array(ccam,','))[ccami]) <> '' AND
data NOT ILIKE '%'||trim((string_to_array(ccam,','))[ccami])||'%'
) subview
GROUP BY 1,2,3
ORDER BY 1,2,3,4
) subview
WHERE w_fiche5_IN.scenario = subview.scenario AND
w_fiche5_IN.fiche5_rss_id = subview.fiche5_rss_id AND
w_fiche5_IN.i = subview.i
;
UPDATE w_fiche5_IN
SET data = overlay(
overlay(
data
placing
ccam_new
from (178+base.cti_to_number(substr(data,119,2))::integer*8+base.cti_to_number(substr(data,121,2))::integer*8) for base.Cti_to_number(substr(data,123,3))::integer*29
)
placing
to_char(length(ccam_new)/29, 'FM000')
from 123 for 3
)
WHERE w_fiche5_IN.scenario <> 'I'
;
EXECUTE '
COPY
(
SELECT data
FROM w_fiche5_IN
WHERE rule = ''GHS''
ORDER BY fiche5_rss_id, scenario, i
)
TO '''||fg_dir||'/files/FICHE5_GRP''
';
DROP TABLE IF EXISTS w_EXEC
;
CREATE TEMP TABLE w_EXEC (result text)
;
TRUNCATE w_EXEC
;
EXECUTE '
COPY w_EXEC (result) FROM PROGRAM ''"'||fg_dir||'/pgm/fg/BIN/'||fg_exe||'.exe" '||fg_dir||'/files/FICHE5_GRP '||fg_dir||'/pgm/fg/TABLES/ 2 '||fg_dir||'/files/FICHE5_GRP.FICUM '||fg_dir||'/temp'';
';
DROP TABLE IF EXISTS w_fiche5_GRP
;
CREATE TEMP TABLE w_fiche5_GRP (data text, fiche5_rss_id bigint DEFAULT 0, ghm_code text DEFAULT '', ghm_id bigint DEFAULT 0, scenario text DEFAULT '')
;
EXECUTE '
COPY w_fiche5_GRP(data) FROM '''||fg_dir||'/temp/FICHE5_GRP.grp''
';
UPDATE w_fiche5_GRP SET
fiche5_rss_id = base.cti_to_number(substr(data,28,10)),
ghm_code = trim(substr(data,3,6)),
scenario = CASE substr(data,46,2) WHEN '10' THEN 'I' WHEN '11' THEN '1' WHEN '12' THEN '2' WHEN '15' THEN 'C' WHEN '19' THEN 'R' ELSE '' END
;
UPDATE w_fiche5_GRP SET
ghm_id = t_ghm.oid
FROM pmsi.t_ghm
WHERE ghm_code = t_ghm.code
;
DROP TABLE IF EXISTS w_fiche5_RDS
;
CREATE TEMP TABLE w_fiche5_RDS (data text,
format text DEFAULT '',
fiche5_rss_id bigint DEFAULT 0,
ghm_code text DEFAULT '',
ghm_id bigint DEFAULT 0,
ghs_code text DEFAULT '',
ghs_id bigint DEFAULT 0,
dp_code text DEFAULT '',
dp_id bigint DEFAULT 0,
nb_exh numeric DEFAULT 0,
is_exb text DEFAULT '1',
nb_exb numeric DEFAULT 0,
scenario text DEFAULT '')
;
EXECUTE '
COPY w_fiche5_RDS(data) FROM '''||fg_dir||'/temp/FICHE5_GRP.rds''
';
UPDATE w_fiche5_RDS SET
fiche5_rss_id = base.cti_to_number(substr(data,1,10)),
format = trim(substr(data,33,3)),
ghm_code = trim(substr(data,38,6)),
ghs_code = trim(substr(data,94,4)),
dp_code = trim(substr(data,210,6)),
nb_exh = base.cti_to_number(substr(data,98,4)),
is_exb = trim(substr(data,102,1)),
nb_exb = base.cti_to_number(substr(data,103,5)),
scenario = CASE substr(data,19,2) WHEN '10' THEN 'I' WHEN '11' THEN '1' WHEN '12' THEN '2' WHEN '15' THEN 'C' WHEN '19' THEN 'R' ELSE '' END
;
UPDATE w_fiche5_RDS SET
ghs_id = t_ghs.oid
FROM pmsi.t_ghs
WHERE ghs_code = to_char(t_ghs.code,'FM0000') OR
ghs_code = t_ghs.code_text
;
UPDATE w_fiche5_RDS SET
dp_id = t_diagnostics.oid
FROM pmsi.t_diagnostics
WHERE dp_code = t_diagnostics.code
;
UPDATE pmsi.p_fiche5_rss SET
initial_ghm_code = CASE WHEN subview.initial_ghm_code <> '' THEN subview.initial_ghm_code ELSE p_fiche5_rss.initial_ghm_code END,
scenar1_ghm_code = CASE WHEN subview.scenar1_ghm_code <> '' THEN subview.scenar1_ghm_code ELSE p_fiche5_rss.scenar1_ghm_code END,
scenar2_ghm_code = CASE WHEN subview.scenar2_ghm_code <> '' THEN subview.scenar2_ghm_code ELSE p_fiche5_rss.scenar2_ghm_code END,
control_ghm_code = CASE WHEN subview.control_ghm_code <> '' THEN subview.control_ghm_code ELSE p_fiche5_rss.control_ghm_code END,
retenu_ghm_code = CASE WHEN subview.retenu_ghm_code <> '' THEN subview.retenu_ghm_code ELSE p_fiche5_rss.retenu_ghm_code END,
initial_ghm_id = CASE WHEN subview.initial_ghm_code <> '' THEN subview.initial_ghm_id ELSE p_fiche5_rss.initial_ghm_id END,
scenar1_ghm_id = CASE WHEN subview.scenar1_ghm_code <> '' THEN subview.scenar1_ghm_id ELSE p_fiche5_rss.scenar1_ghm_id END,
scenar2_ghm_id = CASE WHEN subview.scenar2_ghm_code <> '' THEN subview.scenar2_ghm_id ELSE p_fiche5_rss.scenar2_ghm_id END,
control_ghm_id = CASE WHEN subview.control_ghm_code <> '' THEN subview.control_ghm_id ELSE p_fiche5_rss.control_ghm_id END,
retenu_ghm_id = CASE WHEN subview.retenu_ghm_code <> '' THEN subview.retenu_ghm_id ELSE p_fiche5_rss.retenu_ghm_id END
FROM
(
SELECT fiche5_rss_id,
MAX(CASE WHEN scenario = 'I' THEN ghm_code ELSE '' END) AS initial_ghm_code,
MAX(CASE WHEN scenario = '1' THEN ghm_code ELSE '' END) AS scenar1_ghm_code,
MAX(CASE WHEN scenario = '2' THEN ghm_code ELSE '' END) AS scenar2_ghm_code,
MAX(CASE WHEN scenario = 'C' THEN ghm_code ELSE '' END) AS control_ghm_code,
MAX(CASE WHEN scenario = 'R' THEN ghm_code ELSE '' END) AS retenu_ghm_code,
MAX(CASE WHEN scenario = 'I' THEN ghm_id ELSE 0 END) AS initial_ghm_id,
MAX(CASE WHEN scenario = '1' THEN ghm_id ELSE 0 END) AS scenar1_ghm_id,
MAX(CASE WHEN scenario = '2' THEN ghm_id ELSE 0 END) AS scenar2_ghm_id,
MAX(CASE WHEN scenario = 'C' THEN ghm_id ELSE 0 END) AS control_ghm_id,
MAX(CASE WHEN scenario = 'R' THEN ghm_id ELSE 0 END) AS retenu_ghm_id
FROM w_fiche5_GRP
GROUP BY 1
) subview
WHERE p_fiche5_rss.oid = subview.fiche5_rss_id
;
UPDATE pmsi.p_fiche5_rss SET
initial_dp_code = CASE WHEN subview.initial_dp_code <> '' THEN subview.initial_dp_code ELSE p_fiche5_rss.initial_dp_code END,
scenar1_dp_code = CASE WHEN subview.scenar1_dp_code <> '' THEN subview.scenar1_dp_code ELSE p_fiche5_rss.scenar1_dp_code END,
scenar2_dp_code = CASE WHEN subview.scenar2_dp_code <> '' THEN subview.scenar2_dp_code ELSE p_fiche5_rss.scenar2_dp_code END,
control_dp_code = CASE WHEN subview.control_dp_code <> '' THEN subview.control_dp_code ELSE p_fiche5_rss.control_dp_code END,
retenu_dp_code = CASE WHEN subview.retenu_dp_code <> '' THEN subview.retenu_dp_code ELSE p_fiche5_rss.retenu_dp_code END,
initial_dp_id = CASE WHEN subview.initial_dp_code <> '' THEN subview.initial_dp_id ELSE p_fiche5_rss.initial_dp_id END,
scenar1_dp_id = CASE WHEN subview.scenar1_dp_code <> '' THEN subview.scenar1_dp_id ELSE p_fiche5_rss.scenar1_dp_id END,
scenar2_dp_id = CASE WHEN subview.scenar2_dp_code <> '' THEN subview.scenar2_dp_id ELSE p_fiche5_rss.scenar2_dp_id END,
control_dp_id = CASE WHEN subview.control_dp_code <> '' THEN subview.control_dp_id ELSE p_fiche5_rss.control_dp_id END,
retenu_dp_id = CASE WHEN subview.retenu_dp_code <> '' THEN subview.retenu_dp_id ELSE p_fiche5_rss.retenu_dp_id END,
initial_ghs_code = CASE WHEN subview.initial_ghs_code <> '' THEN subview.initial_ghs_code ELSE p_fiche5_rss.initial_ghs_code END,
scenar1_ghs_code = CASE WHEN subview.scenar1_ghs_code <> '' THEN subview.scenar1_ghs_code ELSE p_fiche5_rss.scenar1_ghs_code END,
scenar2_ghs_code = CASE WHEN subview.scenar2_ghs_code <> '' THEN subview.scenar2_ghs_code ELSE p_fiche5_rss.scenar2_ghs_code END,
control_ghs_code = CASE WHEN subview.control_ghs_code <> '' THEN subview.control_ghs_code ELSE p_fiche5_rss.control_ghs_code END,
retenu_ghs_code = CASE WHEN subview.retenu_ghs_code <> '' THEN subview.retenu_ghs_code ELSE p_fiche5_rss.retenu_ghs_code END,
initial_ghs_id = CASE WHEN subview.initial_ghs_code <> '' THEN subview.initial_ghs_id ELSE p_fiche5_rss.initial_ghs_id END,
scenar1_ghs_id = CASE WHEN subview.scenar1_ghs_code <> '' THEN subview.scenar1_ghs_id ELSE p_fiche5_rss.scenar1_ghs_id END,
scenar2_ghs_id = CASE WHEN subview.scenar2_ghs_code <> '' THEN subview.scenar2_ghs_id ELSE p_fiche5_rss.scenar2_ghs_id END,
control_ghs_id = CASE WHEN subview.control_ghs_code <> '' THEN subview.control_ghs_id ELSE p_fiche5_rss.control_ghs_id END,
retenu_ghs_id = CASE WHEN subview.retenu_ghs_code <> '' THEN subview.retenu_ghs_id ELSE p_fiche5_rss.retenu_ghs_id END,
initial_nb_exh = CASE WHEN subview.initial_nb_exh <> 0 THEN subview.initial_nb_exh ELSE p_fiche5_rss.initial_nb_exh END,
scenar1_nb_exh = CASE WHEN subview.scenar1_nb_exh <> 0 THEN subview.scenar1_nb_exh ELSE p_fiche5_rss.scenar1_nb_exh END,
scenar2_nb_exh = CASE WHEN subview.scenar2_nb_exh <> 0 THEN subview.scenar2_nb_exh ELSE p_fiche5_rss.scenar2_nb_exh END,
control_nb_exh = CASE WHEN subview.control_nb_exh <> 0 THEN subview.control_nb_exh ELSE p_fiche5_rss.control_nb_exh END,
retenu_nb_exh = CASE WHEN subview.retenu_nb_exh <> 0 THEN subview.retenu_nb_exh ELSE p_fiche5_rss.retenu_nb_exh END,
initial_nb_exb = CASE WHEN subview.initial_nb_exb <> 0 THEN subview.initial_nb_exb ELSE p_fiche5_rss.initial_nb_exb END,
scenar1_nb_exb = CASE WHEN subview.scenar1_nb_exb <> 0 THEN subview.scenar1_nb_exb ELSE p_fiche5_rss.scenar1_nb_exb END,
scenar2_nb_exb = CASE WHEN subview.scenar2_nb_exb <> 0 THEN subview.scenar2_nb_exb ELSE p_fiche5_rss.scenar2_nb_exb END,
control_nb_exb = CASE WHEN subview.control_nb_exb <> 0 THEN subview.control_nb_exb ELSE p_fiche5_rss.control_nb_exb END,
retenu_nb_exb = CASE WHEN subview.retenu_nb_exb <> 0 THEN subview.retenu_nb_exb ELSE p_fiche5_rss.retenu_nb_exb END
FROM
(
SELECT fiche5_rss_id,
MAX(CASE WHEN scenario = 'I' THEN dp_code ELSE '' END) AS initial_dp_code,
MAX(CASE WHEN scenario = '1' THEN dp_code ELSE '' END) AS scenar1_dp_code,
MAX(CASE WHEN scenario = '2' THEN dp_code ELSE '' END) AS scenar2_dp_code,
MAX(CASE WHEN scenario = 'C' THEN dp_code ELSE '' END) AS control_dp_code,
MAX(CASE WHEN scenario = 'R' THEN dp_code ELSE '' END) AS retenu_dp_code,
MAX(CASE WHEN scenario = 'I' THEN dp_id ELSE 0 END) AS initial_dp_id,
MAX(CASE WHEN scenario = '1' THEN dp_id ELSE 0 END) AS scenar1_dp_id,
MAX(CASE WHEN scenario = '2' THEN dp_id ELSE 0 END) AS scenar2_dp_id,
MAX(CASE WHEN scenario = 'C' THEN dp_id ELSE 0 END) AS control_dp_id,
MAX(CASE WHEN scenario = 'R' THEN dp_id ELSE 0 END) AS retenu_dp_id,
MAX(CASE WHEN scenario = 'I' THEN ghs_code ELSE '' END) AS initial_ghs_code,
MAX(CASE WHEN scenario = '1' THEN ghs_code ELSE '' END) AS scenar1_ghs_code,
MAX(CASE WHEN scenario = '2' THEN ghs_code ELSE '' END) AS scenar2_ghs_code,
MAX(CASE WHEN scenario = 'C' THEN ghs_code ELSE '' END) AS control_ghs_code,
MAX(CASE WHEN scenario = 'R' THEN ghs_code ELSE '' END) AS retenu_ghs_code,
MAX(CASE WHEN scenario = 'I' THEN ghs_id ELSE 0 END) AS initial_ghs_id,
MAX(CASE WHEN scenario = '1' THEN ghs_id ELSE 0 END) AS scenar1_ghs_id,
MAX(CASE WHEN scenario = '2' THEN ghs_id ELSE 0 END) AS scenar2_ghs_id,
MAX(CASE WHEN scenario = 'C' THEN ghs_id ELSE 0 END) AS control_ghs_id,
MAX(CASE WHEN scenario = 'R' THEN ghs_id ELSE 0 END) AS retenu_ghs_id,
MAX(CASE WHEN scenario = 'I' THEN nb_exh ELSE 0 END) AS initial_nb_exh,
MAX(CASE WHEN scenario = '1' THEN nb_exh ELSE 0 END) AS scenar1_nb_exh,
MAX(CASE WHEN scenario = '2' THEN nb_exh ELSE 0 END) AS scenar2_nb_exh,
MAX(CASE WHEN scenario = 'C' THEN nb_exh ELSE 0 END) AS control_nb_exh,
MAX(CASE WHEN scenario = 'R' THEN nb_exh ELSE 0 END) AS retenu_nb_exh,
MAX(CASE WHEN scenario = 'I' THEN nb_exb ELSE 0 END) AS initial_nb_exb,
MAX(CASE WHEN scenario = '1' THEN nb_exb ELSE 0 END) AS scenar1_nb_exb,
MAX(CASE WHEN scenario = '2' THEN nb_exb ELSE 0 END) AS scenar2_nb_exb,
MAX(CASE WHEN scenario = 'C' THEN nb_exb ELSE 0 END) AS control_nb_exb,
MAX(CASE WHEN scenario = 'R' THEN nb_exb ELSE 0 END) AS retenu_nb_exb
FROM w_fiche5_RDS
GROUP BY 1
) subview
WHERE p_fiche5_rss.oid = fiche5_rss_id
;
UPDATE pmsi.p_fiche5_rss SET
scenar1_ghm_code = CASE
WHEN scenar1_rule = 'GHS' THEN p_fiche5_rss.scenar1_ghm_code
ELSE scenar1_rule END
;
UPDATE pmsi.p_fiche5_rss SET
scenar1_ghm_code = CASE
WHEN scenar1_rule = 'GHS' OR scenar1_rule LIKE 'CF%' THEN p_fiche5_rss.scenar1_ghm_code
ELSE scenar1_rule END,
scenar1_ghm_id = CASE
WHEN scenar1_rule = 'GHS' OR scenar1_rule LIKE 'CF%' THEN p_fiche5_rss.scenar1_ghm_id
ELSE 0 END,
scenar2_ghm_code = CASE
WHEN scenar2_rule = 'GHS' OR scenar2_rule LIKE 'CF%' THEN p_fiche5_rss.scenar2_ghm_code
ELSE scenar2_rule END,
scenar2_ghm_id = CASE
WHEN scenar2_rule = 'GHS' OR scenar2_rule LIKE 'CF%' THEN p_fiche5_rss.scenar2_ghm_id
ELSE 0 END,
control_ghm_code = CASE
WHEN control_rule = 'GHS' OR control_rule LIKE 'CF%' THEN p_fiche5_rss.control_ghm_code
ELSE control_rule END,
control_ghm_id = CASE
WHEN control_rule = 'GHS' OR control_rule LIKE 'CF%' THEN p_fiche5_rss.control_ghm_id
ELSE 0 END,
retenu_ghm_code = CASE
WHEN retenu_rule = 'GHS' OR retenu_rule LIKE 'CF%' THEN p_fiche5_rss.retenu_ghm_code
ELSE retenu_rule END,
retenu_ghm_id = CASE
WHEN retenu_rule = 'GHS' OR retenu_rule LIKE 'CF%' THEN p_fiche5_rss.retenu_ghm_id
ELSE 0 END
;
-- Valorisation
DROP TABLE IF EXISTS w_ghs;
CREATE TEMP TABLE w_ghs
(
oid bigint,
type_tarif text,
index_tarif integer,
date_debut_tarif date,
date_fin_tarif date,
tarif_ghs numeric,
borne_basse numeric,
borne_haute numeric,
tarif_exh numeric,
forfait_exb numeric,
tarif_exb numeric
)
;
PERFORM base.cti_execute('
INSERT INTO w_ghs
SELECT
oid,
'''||type_tarif||'''::text AS type_tarif,
'||i||'::numeric AS index_tarif,
date_debut_'||type_tarif_field||'_'||i||',
date_fin_'||type_tarif_field||'_'||i||',
tarif_ghs_'||type_tarif_field||'_'||i||',
borne_basse_'||type_tarif_field||'_'||i||',
borne_haute_'||type_tarif_field||'_'||i||',
tarif_exh_'||type_tarif_field||'_'||i||',
forfait_exb_'||type_tarif_field||'_'||i||',
tarif_exb_'||type_tarif_field||'_'||i||'
FROM pmsi.t_ghs
WHERE date_debut_'||type_tarif_field||'_'||i||' <> ''20991231'' AND
date_fin_'||type_tarif_field||'_'||i||' >= ''20170131''
',1)
FROM
(
SELECT '1' AS type_tarif, 'public'::text AS type_tarif_field
UNION
SELECT '2' AS type_tarif, 'prive'::text AS type_tarif_field
) subview1,
(
SELECT generate_series(1,9) AS i
) subview2
;
PERFORM base.cti_execute('
UPDATE pmsi.p_fiche5_rss SET
'||scenar||'_ghs_montant_total = round(w_ghs.tarif_ghs * coefficient_mco,2),
'||scenar||'_exh_montant_total = round(
CASE
WHEN duree_sejour + CASE WHEN mode_sortie IN (''9'') THEN 1 ELSE 0 END > borne_haute AND borne_haute > 0
THEN tarif_exh * (duree_sejour + CASE WHEN mode_sortie IN (''9'') THEN 1 ELSE 0 END - borne_haute) * coefficient_mco
ELSE 0 END
,2),
'||scenar||'_exb_montant_total = round(
0 - CASE
WHEN borne_basse = 0 OR duree_sejour + CASE WHEN mode_sortie IN (''9'') THEN 1 ELSE 0 END >= borne_basse OR mode_sortie = ''9'' THEN 0
WHEN forfait_exb > 0 THEN forfait_exb * coefficient_mco
WHEN forfait_exb = 0 AND tarif_exb > 0 AND duree_sejour = 0 THEN (tarif_ghs * coefficient_mco) - (tarif_exb / 2 * coefficient_mco)
WHEN forfait_exb = 0 AND tarif_exb > 0 AND duree_sejour > 0 THEN (tarif_exb * (borne_basse-duree_sejour)) * coefficient_mco
ELSE 0 END
,2)
FROM w_ghs
WHERE p_fiche5_rss.'||scenar||'_ghs_id = w_ghs.oid AND
p_fiche5_rss.type_tarif = w_ghs.type_tarif AND
p_fiche5_rss.date_sortie BETWEEN w_ghs.date_debut_tarif AND w_ghs.date_fin_tarif
',1)
FROM
(
SELECT 'initial'::text AS scenar
UNION
SELECT 'scenar1'::text AS scenar
UNION
SELECT 'scenar2'::text AS scenar
UNION
SELECT 'control'::text AS scenar
UNION
SELECT 'retenu'::text AS scenar
) subview
;
-- Facturation externe
UPDATE pmsi.p_fiche5_rss SET
scenar1_ghs_montant_total = t_prestation_tarif.tarif,
scenar1_exh_montant_total = 0,
scenar1_exb_montant_total = 0
FROM pmsi.t_prestations
JOIN pmsi.t_prestation_tarif ON prestation_id = t_prestations.oid
WHERE scenar1_rule <> 'GHS' AND scenar1_rule <> '' AND
t_prestations.code = scenar1_rule AND
p_fiche5_rss.date_sortie BETWEEN t_prestation_tarif.date_debut AND t_prestation_tarif.date_fin AND
type_ets = '2'
;
UPDATE pmsi.p_fiche5_rss SET
scenar1_ghs_montant_total = 0,
scenar1_exh_montant_total = 0,
scenar1_exb_montant_total = 0
FROM pmsi.t_prestations
JOIN pmsi.t_prestation_tarif ON prestation_id = t_prestations.oid
WHERE scenar1_rule = 'EXT'
;
UPDATE pmsi.p_fiche5_rss SET
scenar2_ghs_montant_total = t_prestation_tarif.tarif,
scenar2_exh_montant_total = 0,
scenar2_exb_montant_total = 0
FROM pmsi.t_prestations
JOIN pmsi.t_prestation_tarif ON prestation_id = t_prestations.oid
WHERE scenar2_rule <> 'GHS' AND scenar2_rule <> '' AND
t_prestations.code = scenar2_rule AND
p_fiche5_rss.date_sortie BETWEEN t_prestation_tarif.date_debut AND t_prestation_tarif.date_fin AND
type_ets = '2'
;
UPDATE pmsi.p_fiche5_rss SET
scenar2_ghs_montant_total = 0,
scenar2_exh_montant_total = 0,
scenar2_exb_montant_total = 0
FROM pmsi.t_prestations
JOIN pmsi.t_prestation_tarif ON prestation_id = t_prestations.oid
WHERE scenar2_rule = 'EXT'
;
UPDATE pmsi.p_fiche5_rss SET
control_ghs_montant_total = t_prestation_tarif.tarif,
control_exh_montant_total = 0,
control_exb_montant_total = 0
FROM pmsi.t_prestations
JOIN pmsi.t_prestation_tarif ON prestation_id = t_prestations.oid
WHERE control_rule <> 'GHS' AND control_rule <> '' AND
t_prestations.code = control_rule AND
p_fiche5_rss.date_sortie BETWEEN t_prestation_tarif.date_debut AND t_prestation_tarif.date_fin AND
type_ets = '2'
;
UPDATE pmsi.p_fiche5_rss SET
control_ghs_montant_total = 0,
control_exh_montant_total = 0,
control_exb_montant_total = 0
FROM pmsi.t_prestations
JOIN pmsi.t_prestation_tarif ON prestation_id = t_prestations.oid
WHERE control_rule = 'EXT'
;
UPDATE pmsi.p_fiche5_rss SET
retenu_ghs_montant_total = t_prestation_tarif.tarif,
retenu_exh_montant_total = 0,
retenu_exb_montant_total = 0
FROM pmsi.t_prestations
JOIN pmsi.t_prestation_tarif ON prestation_id = t_prestations.oid
WHERE retenu_rule <> 'GHS' AND retenu_rule <> '' AND
t_prestations.code = retenu_rule AND
p_fiche5_rss.date_sortie BETWEEN t_prestation_tarif.date_debut AND t_prestation_tarif.date_fin AND
type_ets = '2'
;
UPDATE pmsi.p_fiche5_rss SET
retenu_ghs_montant_total = 0,
retenu_exh_montant_total = 0,
retenu_exb_montant_total = 0
FROM pmsi.t_prestations
JOIN pmsi.t_prestation_tarif ON prestation_id = t_prestations.oid
WHERE retenu_rule = 'EXT'
;
-- Recopie selon CF
UPDATE pmsi.p_fiche5_rss SET
scenar1_rum_um_code = initial_rum_um_code,
scenar1_rum_dp_code = initial_rum_dp_code,
scenar1_rum_dr_code = initial_rum_dr_code,
scenar1_rum_da_code = initial_rum_da_code,
scenar1_ghs_id = initial_ghs_id,
scenar1_ghs_code = initial_ghs_code,
scenar1_ghm_id = initial_ghm_id,
scenar1_ghm_code = initial_ghm_code,
scenar1_ghs_tarif = initial_ghs_tarif,
scenar1_ghs_montant_total = initial_ghs_montant_total,
scenar1_exb_montant_total = initial_exb_montant_total,
scenar1_exh_montant_total = initial_exh_montant_total,
scenar1_ghs_montant_amo = initial_ghs_montant_amo,
scenar1_exb_montant_amo = initial_exb_montant_amo,
scenar1_exh_montant_amo = initial_exh_montant_amo
WHERE scenar1_rule = '' OR scenar1_rule IS NULL
;
UPDATE pmsi.p_fiche5_rss SET
scenar2_rum_um_code = scenar1_rum_um_code,
scenar2_rum_dp_code = scenar1_rum_dp_code,
scenar2_rum_dr_code = scenar1_rum_dr_code,
scenar2_rum_da_code = scenar1_rum_da_code,
scenar2_ghs_id = scenar1_ghs_id,
scenar2_ghs_code = scenar1_ghs_code,
scenar2_ghm_id = scenar1_ghm_id,
scenar2_ghm_code = scenar1_ghm_code,
scenar2_ghs_tarif = scenar1_ghs_tarif,
scenar2_ghs_montant_total = scenar1_ghs_montant_total,
scenar2_exb_montant_total = scenar1_exb_montant_total,
scenar2_exh_montant_total = scenar1_exh_montant_total,
scenar2_ghs_montant_amo = scenar1_ghs_montant_amo,
scenar2_exb_montant_amo = scenar1_exb_montant_amo,
scenar2_exh_montant_amo = scenar1_exh_montant_amo
WHERE scenar2_rule = 'CFSC1' OR
scenar2_rule = '' OR
scenar2_rule IS NULL
;
UPDATE pmsi.p_fiche5_rss SET
control_rum_um_code = initial_rum_um_code,
control_rum_dp_code = initial_rum_dp_code,
control_rum_dr_code = initial_rum_dr_code,
control_rum_da_code = initial_rum_da_code,
control_ghs_id = initial_ghs_id,
control_ghs_code = initial_ghs_code,
control_ghm_id = initial_ghm_id,
control_ghm_code = initial_ghm_code,
control_ghs_tarif = initial_ghs_tarif,
control_ghs_montant_total = initial_ghs_montant_total,
control_exb_montant_total = initial_exb_montant_total,
control_exh_montant_total = initial_exh_montant_total,
control_ghs_montant_amo = initial_ghs_montant_amo,
control_exb_montant_amo = initial_exb_montant_amo,
control_exh_montant_amo = initial_exh_montant_amo
WHERE control_rule = 'OKAM' OR
control_rule IS NULL OR
control_rule = ''
;
UPDATE pmsi.p_fiche5_rss SET
control_rum_um_code = scenar1_rum_um_code,
control_rum_dp_code = scenar1_rum_dp_code,
control_rum_dr_code = scenar1_rum_dr_code,
control_rum_da_code = scenar1_rum_da_code,
control_ghs_id = scenar1_ghs_id,
control_ghs_code = scenar1_ghs_code,
control_ghm_id = scenar1_ghm_id,
control_ghm_code = scenar1_ghm_code,
control_ghs_tarif = scenar1_ghs_tarif,
control_ghs_montant_total = scenar1_ghs_montant_total,
control_exb_montant_total = scenar1_exb_montant_total,
control_exh_montant_total = scenar1_exh_montant_total,
control_ghs_montant_amo = scenar1_ghs_montant_amo,
control_exb_montant_amo = scenar1_exb_montant_amo,
control_exh_montant_amo = scenar1_exh_montant_amo
WHERE control_rule = 'CFSC1'
;
UPDATE pmsi.p_fiche5_rss SET
control_rum_um_code = scenar2_rum_um_code,
control_rum_dp_code = scenar2_rum_dp_code,
control_rum_dr_code = scenar2_rum_dr_code,
control_rum_da_code = scenar2_rum_da_code,
control_ghs_id = scenar2_ghs_id,
control_ghs_code = scenar2_ghs_code,
control_ghm_id = scenar2_ghm_id,
control_ghm_code = scenar2_ghm_code,
control_ghs_tarif = scenar2_ghs_tarif,
control_ghs_montant_total = scenar2_ghs_montant_total,
control_exb_montant_total = scenar2_exb_montant_total,
control_exh_montant_total = scenar2_exh_montant_total,
control_ghs_montant_amo = scenar2_ghs_montant_amo,
control_exb_montant_amo = scenar2_exb_montant_amo,
control_exh_montant_amo = scenar2_exh_montant_amo
WHERE control_rule = 'CFSC2'
;
UPDATE pmsi.p_fiche5_rss SET
retenu_rum_um_code = initial_rum_um_code,
retenu_rum_dp_code = initial_rum_dp_code,
retenu_rum_dr_code = initial_rum_dr_code,
retenu_rum_da_code = initial_rum_da_code,
retenu_ghs_id = initial_ghs_id,
retenu_ghs_code = initial_ghs_code,
retenu_ghm_id = initial_ghm_id,
retenu_ghm_code = initial_ghm_code,
retenu_ghs_tarif = initial_ghs_tarif,
retenu_ghs_montant_total = initial_ghs_montant_total,
retenu_exb_montant_total = initial_exb_montant_total,
retenu_exh_montant_total = initial_exh_montant_total,
retenu_ghs_montant_amo = initial_ghs_montant_amo,
retenu_exb_montant_amo = initial_exb_montant_amo,
retenu_exh_montant_amo = initial_exh_montant_amo
WHERE retenu_rule = 'OKAM' OR
retenu_rule = '' OR
retenu_rule IS NULL
;
UPDATE pmsi.p_fiche5_rss SET
retenu_rum_um_code = scenar1_rum_um_code,
retenu_rum_dp_code = scenar1_rum_dp_code,
retenu_rum_dr_code = scenar1_rum_dr_code,
retenu_rum_da_code = scenar1_rum_da_code,
retenu_ghs_id = scenar1_ghs_id,
retenu_ghs_code = scenar1_ghs_code,
retenu_ghm_id = scenar1_ghm_id,
retenu_ghm_code = scenar1_ghm_code,
retenu_ghs_tarif = scenar1_ghs_tarif,
retenu_ghs_montant_total = scenar1_ghs_montant_total,
retenu_exb_montant_total = scenar1_exb_montant_total,
retenu_exh_montant_total = scenar1_exh_montant_total,
retenu_ghs_montant_amo = scenar1_ghs_montant_amo,
retenu_exb_montant_amo = scenar1_exb_montant_amo,
retenu_exh_montant_amo = scenar1_exh_montant_amo
WHERE retenu_rule = 'CFSC1'
;
UPDATE pmsi.p_fiche5_rss SET
retenu_rum_um_code = scenar2_rum_um_code,
retenu_rum_dp_code = scenar2_rum_dp_code,
retenu_rum_dr_code = scenar2_rum_dr_code,
retenu_rum_da_code = scenar2_rum_da_code,
retenu_ghs_id = scenar2_ghs_id,
retenu_ghs_code = scenar2_ghs_code,
retenu_ghm_id = scenar2_ghm_id,
retenu_ghm_code = scenar2_ghm_code,
retenu_ghs_tarif = scenar2_ghs_tarif,
retenu_ghs_montant_total = scenar2_ghs_montant_total,
retenu_exb_montant_total = scenar2_exb_montant_total,
retenu_exh_montant_total = scenar2_exh_montant_total,
retenu_ghs_montant_amo = scenar2_ghs_montant_amo,
retenu_exb_montant_amo = scenar2_exb_montant_amo,
retenu_exh_montant_amo = scenar2_exh_montant_amo
WHERE retenu_rule = 'CFSC2'
;
UPDATE pmsi.p_fiche5_rss SET
retenu_rum_um_code = control_rum_um_code,
retenu_rum_dp_code = control_rum_dp_code,
retenu_rum_dr_code = control_rum_dr_code,
retenu_rum_da_code = control_rum_da_code,
retenu_ghs_id = control_ghs_id,
retenu_ghs_code = control_ghs_code,
retenu_ghm_id = control_ghm_id,
retenu_ghm_code = control_ghm_code,
retenu_ghs_tarif = control_ghs_tarif,
retenu_ghs_montant_total = control_ghs_montant_total,
retenu_exb_montant_total = control_exb_montant_total,
retenu_exh_montant_total = control_exh_montant_total,
retenu_ghs_montant_amo = control_ghs_montant_amo,
retenu_exb_montant_amo = control_exb_montant_amo,
retenu_exh_montant_amo = control_exh_montant_amo
WHERE retenu_rule = 'CFCTL'
;
-- SI séjour pas facturé à AMO, retenir montant groupage initial comme montant facturé
UPDATE pmsi.p_fiche5_rss SET
facture_ghs_id = initial_ghs_id,
facture_ghs_code = initial_ghs_code,
facture_ghs_tarif = initial_ghs_tarif,
facture_ghs_montant_total = initial_ghs_montant_total,
facture_exb_montant_total = initial_exb_montant_total,
facture_exh_montant_total = initial_exh_montant_total,
facture_nb_exh = initial_nb_exh,
facture_nb_exb = initial_nb_exb
WHERE facture_ghs_montant_total = 0 AND
facture_ghm_code = initial_ghm_code
;
return 'OK'
;
RETURN 'OK';
END;