return: text lang: plpgsql parameters: p0: type: bigint name: i_enquete_id default: "0" src: | DECLARE result TEXT; BEGIN DROP TABLE IF EXISTS w_fiche5_rss; CREATE TEMP TABLE w_fiche5_rss AS SELECT P_fiche5_rss.* FROM pmsi.P_fiche5_rss JOIN pmsi.t_fiche5_enquete ON enquete_id = t_fiche5_enquete.oid WHERE i_enquete_id = 0 OR t_fiche5_enquete.oid = i_enquete_id ; -- UM, DP, DR UPDATE pmsi.p_fiche5_rss SET initial_rum_um_code = subview.initial_rum_um_code, initial_rum_dp_code = subview.initial_rum_dp_code, initial_rum_dr_code = subview.initial_rum_dr_code FROM ( SELECT fiche5_rss_id, ARRAY[ MAX(CASE WHEN index_rum = 01 THEN um ELSE '' END), MAX(CASE WHEN index_rum = 02 THEN um ELSE '' END), MAX(CASE WHEN index_rum = 03 THEN um ELSE '' END), MAX(CASE WHEN index_rum = 04 THEN um ELSE '' END), MAX(CASE WHEN index_rum = 05 THEN um ELSE '' END), MAX(CASE WHEN index_rum = 06 THEN um ELSE '' END), MAX(CASE WHEN index_rum = 07 THEN um ELSE '' END), MAX(CASE WHEN index_rum = 08 THEN um ELSE '' END), MAX(CASE WHEN index_rum = 09 THEN um ELSE '' END), MAX(CASE WHEN index_rum = 10 THEN um ELSE '' END) ] AS initial_rum_um_code, ARRAY[ MAX(CASE WHEN index_rum = 01 THEN dp ELSE '' END), MAX(CASE WHEN index_rum = 02 THEN dp ELSE '' END), MAX(CASE WHEN index_rum = 03 THEN dp ELSE '' END), MAX(CASE WHEN index_rum = 04 THEN dp ELSE '' END), MAX(CASE WHEN index_rum = 05 THEN dp ELSE '' END), MAX(CASE WHEN index_rum = 06 THEN dp ELSE '' END), MAX(CASE WHEN index_rum = 07 THEN dp ELSE '' END), MAX(CASE WHEN index_rum = 08 THEN dp ELSE '' END), MAX(CASE WHEN index_rum = 09 THEN dp ELSE '' END), MAX(CASE WHEN index_rum = 10 THEN dp ELSE '' END) ] AS initial_rum_dp_code, ARRAY[ MAX(CASE WHEN index_rum = 01 THEN dr ELSE '' END), MAX(CASE WHEN index_rum = 02 THEN dr ELSE '' END), MAX(CASE WHEN index_rum = 03 THEN dr ELSE '' END), MAX(CASE WHEN index_rum = 04 THEN dr ELSE '' END), MAX(CASE WHEN index_rum = 05 THEN dr ELSE '' END), MAX(CASE WHEN index_rum = 06 THEN dr ELSE '' END), MAX(CASE WHEN index_rum = 07 THEN dr ELSE '' END), MAX(CASE WHEN index_rum = 08 THEN dr ELSE '' END), MAX(CASE WHEN index_rum = 09 THEN dr ELSE '' END), MAX(CASE WHEN index_rum = 10 THEN dr ELSE '' END) ] AS initial_rum_dr_code FROM ( SELECT w_fiche5_rss.oid AS fiche5_rss_id, i AS index_rum, trim(substr(initial_rum_in[i],87,4)) AS um, trim(substr(initial_rum_in[i],141,8)) AS dp, trim(substr(initial_rum_in[i],149,8)) AS dr FROM w_fiche5_rss JOIN generate_series (1 , 10) AS i ON initial_rum_in[i] <> '' ) subview GROUP BY 1 ) subview WHERE p_fiche5_rss.oid = subview.fiche5_rss_id AND ( p_fiche5_rss.initial_rum_um_code IS DISTINCT FROM subview.initial_rum_um_code OR p_fiche5_rss.initial_rum_dp_code IS DISTINCT FROM subview.initial_rum_dp_code OR p_fiche5_rss.initial_rum_dr_code IS DISTINCT FROM subview.initial_rum_dr_code ) ; -- D.A. UPDATE pmsi.p_fiche5_rss SET initial_rum_da_code = subview.initial_rum_da_code FROM w_fiche5_rss LEFT JOIN ( SELECT fiche5_rss_id, ARRAY[ MAX(CASE WHEN index_rum = 01 THEN codes_das ELSE '' END), MAX(CASE WHEN index_rum = 02 THEN codes_das ELSE '' END), MAX(CASE WHEN index_rum = 03 THEN codes_das ELSE '' END), MAX(CASE WHEN index_rum = 04 THEN codes_das ELSE '' END), MAX(CASE WHEN index_rum = 05 THEN codes_das ELSE '' END), MAX(CASE WHEN index_rum = 06 THEN codes_das ELSE '' END), MAX(CASE WHEN index_rum = 07 THEN codes_das ELSE '' END), MAX(CASE WHEN index_rum = 08 THEN codes_das ELSE '' END), MAX(CASE WHEN index_rum = 09 THEN codes_das ELSE '' END), MAX(CASE WHEN index_rum = 10 THEN codes_das ELSE '' END) ] AS initial_rum_da_code FROM ( SELECT fiche5_rss_id, index_rum, array_to_string(base.cti_array_accum(code_da),', ') AS codes_das FROM ( SELECT fiche5_rss_id, index_rum, trim(substr(buff_das,((j-1)*8)+1,8)) AS code_da FROM ( SELECT w_fiche5_rss.oid AS fiche5_rss_id, i AS index_rum, base.cti_to_number(substr(initial_rum_in[i],134,2))::integer AS nb_das, substr(initial_rum_in[i], 193::integer) AS buff_das FROM w_fiche5_rss JOIN generate_series (1 , 10) AS i ON initial_rum_in[i] <> '' ) subview JOIN generate_series (1 , nb_das) AS j ON 1=1 GROUP BY 1,2,3 ORDER BY 1,2,3 ) subview GROUP BY 1,2 ) subview GROUP BY 1 ) subview ON w_fiche5_rss.oid = fiche5_rss_id WHERE p_fiche5_rss.oid = w_fiche5_rss.oid AND p_fiche5_rss.initial_rum_da_code IS DISTINCT FROM COALESCE(subview.initial_rum_da_code,ARRAY['']) ; -- Actes UPDATE pmsi.p_fiche5_rss SET initial_rum_ccam_code = subview.initial_rum_ccam_code FROM w_fiche5_rss LEFT JOIN ( SELECT fiche5_rss_id, ARRAY[ MAX(CASE WHEN index_rum = 01 THEN codes_actes ELSE '' END), MAX(CASE WHEN index_rum = 02 THEN codes_actes ELSE '' END), MAX(CASE WHEN index_rum = 03 THEN codes_actes ELSE '' END), MAX(CASE WHEN index_rum = 04 THEN codes_actes ELSE '' END), MAX(CASE WHEN index_rum = 05 THEN codes_actes ELSE '' END), MAX(CASE WHEN index_rum = 06 THEN codes_actes ELSE '' END), MAX(CASE WHEN index_rum = 07 THEN codes_actes ELSE '' END), MAX(CASE WHEN index_rum = 08 THEN codes_actes ELSE '' END), MAX(CASE WHEN index_rum = 09 THEN codes_actes ELSE '' END), MAX(CASE WHEN index_rum = 10 THEN codes_actes ELSE '' END) ] AS initial_rum_ccam_code FROM ( SELECT fiche5_rss_id, index_rum, array_to_string(base.cti_array_accum(code_acte),', ') AS codes_actes FROM ( SELECT fiche5_rss_id, index_rum, substr(buff_actes,((j-1)*29)+9,7) AS code_acte FROM ( SELECT w_fiche5_rss.oid AS fiche5_rss_id, i AS index_rum, base.cti_to_number(substr(initial_rum_in[i],138,3))::integer AS nb_actes, substr(initial_rum_in[i], 193+ base.cti_to_number(substr(initial_rum_in[i],134,2))::integer*8+ base.cti_to_number(substr(initial_rum_in[i],136,2))::integer*8) AS buff_actes FROM w_fiche5_rss JOIN generate_series (1 , 10) AS i ON initial_rum_in[i] <> '' ) subview JOIN generate_series (1 , nb_actes) AS j ON 1=1 GROUP BY 1,2,3 ORDER BY 1,2,3 ) subview GROUP BY 1,2 ) subview GROUP BY 1 ) subview ON w_fiche5_rss.oid = fiche5_rss_id WHERE p_fiche5_rss.oid = w_fiche5_rss.oid AND p_fiche5_rss.initial_rum_ccam_code IS DISTINCT FROM COALESCE(subview.initial_rum_ccam_code,ARRAY['']) ; -- Initialisation des nouveaux champs 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 ; return 'OK' ; RETURN 'OK'; END;