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.
 
 

1882 lines
101 KiB

return: text
lang: plpgsql
parameters:
p0:
type: text
name: i_valosej_path
p1:
type: text
name: i_schema
p2:
type: bigint
name: i_import_id
src: |
DECLARE
v_col text; -- to keep column names in each iteration
v_sqlcmd text;
v_annee numeric; -- annee du fichier VALOSEJ
BEGIN
RAISE NOTICE '% | TRAITEMENT DU FICHIER : %', to_char(CURRENT_TIMESTAMP, 'YYYY-MM-DD HH24:MI:ss'), i_valosej_path;
RAISE NOTICE '% | SCHEMA : %', to_char(CURRENT_TIMESTAMP, 'YYYY-MM-DD HH24:MI:ss'), i_schema;
RAISE NOTICE '% | IMPORT n° : %', to_char(CURRENT_TIMESTAMP, 'YYYY-MM-DD HH24:MI:ss'), i_import_id;
/* *************************************
Pré-chargement pour nom des colonnes
****************************************/
DROP TABLE IF EXISTS in_valosej CASCADE;
DROP SEQUENCE IF EXISTS s_valosej;
CREATE TEMP SEQUENCE s_valosej;
CREATE TEMP TABLE in_valosej (
ligne numeric DEFAULT nextval('s_valosej'::regclass),
data text,
data_array text[]
);
v_sqlcmd = 'COPY in_valosej (data) FROM ''' || i_valosej_path || ''' WITH delimiter ''²''';
EXECUTE v_sqlcmd;
DELETE FROM in_valosej where ligne > 1;
UPDATE in_valosej SET data_array = string_to_array(data,chr(9));
UPDATE in_valosej SET data_array[9] = 'COEFTRANS' WHERE data_array[9] ILIKE 'COEFSEG';
ALTER TABLE in_valosej DROP COLUMN "data";
/* ***********************************
Peuplement de la table valosej
**************************************/
DROP TABLE IF EXISTS temp_table;
CREATE TEMP TABLE temp_table ();
-- Ajout des colonnes avec le bon nom
FOR v_col IN (SELECT UNNEST(data_array) from in_valosej)
LOOP
EXECUTE FORMAT ('ALTER TABLE temp_table ADD COLUMN %s text;', v_col);
END LOOP;
-- copy the data from csv file
EXECUTE FORMAT ('COPY temp_table FROM %L WITH DELIMITER E''\t'' CSV HEADER', i_valosej_path);
IF (SELECT count(*) FROM temp_table) < 5 THEN
RETURN 'KO. Le format de la table VALOSEJ est incorrect (pas assez de lignes)';
END IF;
UPDATE temp_table SET
no_rss = trim(no_rss),
no_admin = trim(no_admin);
DROP TABLE IF EXISTS temp.p_valosej;
CREATE TABLE temp.p_valosej AS SELECT * FROM temp_table;
DROP TABLE temp_table;
DROP TABLE in_valosej;
-- Detection de l'annee du ficheir VALOSEJ
-- Plutot que de faire un max de l'annee des dates de sortie,
-- on regarde en quelle annee il y a eu le plus de sorties
-- afin de s'affranchir des eventuels RSS sortis hors periode
WITH w_cumul AS
(
SELECT
extract('year' FROM to_date(date_sor, 'DD/MM/YYYY')) as annee,
count(*) as nombre
FROM temp.p_valosej
GROUP BY 1
ORDER BY 2 DESC
LIMIT 1
)
SELECT
annee
FROM
w_cumul
INTO
v_annee;
RAISE NOTICE '% | Annee du lot : %', to_char(CURRENT_TIMESTAMP, 'YYYY-MM-DD HH24:MI:ss'), v_annee;
--CREATE INDEX p_walosej_ik_no_rss ON temp.p_valosej USING btree (no_rss);
RAISE NOTICE '% | COLLECTE DES PRESTATIONS GENEREES', to_char(CURRENT_TIMESTAMP, 'YYYY-MM-DD HH24:MI:ss');
EXECUTE FORMAT ('
DROP TABLE IF EXISTS w_valocti;
CREATE TEMP TABLE w_valocti AS
SELECT
p_rss.no_rss,
p_rss.oid AS rss_id,
traitement_epmsi, t_prestations.code AS prestation_code,
prestation_id,
SUM(prix_unitaire) AS prix_unitaire,
SUM(p_rsf_detail.base_remboursement) AS base_remboursement,
SUM(p_rsf_detail.sejour_remboursable) AS sejour_remboursable,
SUM(base_remboursement_sauf_transition_sauf_ame) AS base_remboursement_sauf_transition_sauf_ame,
count(*) AS nb
FROM %I.p_rsf_detail
JOIN %I.p_rss ON p_rss.oid = p_rsf_detail.rss_id
JOIN pmsi.t_prestations ON prestation_id = t_prestations.oid
WHERE 1=1
AND import_id = %s
AND est_ligne_rss IS DISTINCT FROM ''0''
GROUP BY 1,2,3,4,5
', i_schema, i_schema, i_import_id);
RAISE NOTICE '% | MAINTENANCE %.p_rsf_detail', to_char(CURRENT_TIMESTAMP, 'YYYY-MM-DD HH24:MI:ss'), i_schema;
PERFORM FORMAT ('VACUUM FULL ANALYSE %I.p_rsf_detail', i_schema);
RAISE NOTICE '% | RETRO COMPATIBILITE ENTRE LES FORMATS VALOSEJ', to_char(CURRENT_TIMESTAMP, 'YYYY-MM-DD HH24:MI:ss');
PERFORM base.cti_add_column_if_not_exists('temp.p_valosej', 'coefp', 'text');
PERFORM base.cti_add_column_if_not_exists('temp.p_valosej', 'coefrep', 'text');
PERFORM base.cti_add_column_if_not_exists('temp.p_valosej', 'ghsmin', 'text');
PERFORM base.cti_add_column_if_not_exists('temp.p_valosej', 'ghsminam', 'text');
PERFORM base.cti_add_column_if_not_exists('temp.p_valosej', 'mnt_9610', 'text');
PERFORM base.cti_add_column_if_not_exists('temp.p_valosej', 'mnt_9615', 'text');
PERFORM base.cti_add_column_if_not_exists('temp.p_valosej', 'mnt_9619', 'text');
PERFORM base.cti_add_column_if_not_exists('temp.p_valosej', 'mnt_9620', 'text');
PERFORM base.cti_add_column_if_not_exists('temp.p_valosej', 'mnt_9621', 'text');
PERFORM base.cti_add_column_if_not_exists('temp.p_valosej', 'mnt_9622', 'text');
PERFORM base.cti_add_column_if_not_exists('temp.p_valosej', 'mnt_9623', 'text');
PERFORM base.cti_add_column_if_not_exists('temp.p_valosej', 'mnt_9625', 'text');
PERFORM base.cti_add_column_if_not_exists('temp.p_valosej', 'mnt_9631', 'text');
PERFORM base.cti_add_column_if_not_exists('temp.p_valosej', 'mnt_9632', 'text');
PERFORM base.cti_add_column_if_not_exists('temp.p_valosej', 'mnt_9633', 'text');
PERFORM base.cti_add_column_if_not_exists('temp.p_valosej', 'mnt_ant', 'text');
PERFORM base.cti_add_column_if_not_exists('temp.p_valosej', 'mnt_caisson', 'text');
PERFORM base.cti_add_column_if_not_exists('temp.p_valosej', 'mnt_dip', 'text');
PERFORM base.cti_add_column_if_not_exists('temp.p_valosej', 'mnt_exh', 'text');
PERFORM base.cti_add_column_if_not_exists('temp.p_valosej', 'mnt_exinf', 'text');
PERFORM base.cti_add_column_if_not_exists('temp.p_valosej', 'mnt_ghs', 'text');
PERFORM base.cti_add_column_if_not_exists('temp.p_valosej', 'mnt_ghs50', 'text');
PERFORM base.cti_add_column_if_not_exists('temp.p_valosej', 'mnt_ivg', 'text');
PERFORM base.cti_add_column_if_not_exists('temp.p_valosej', 'mnt_nn1', 'text');
PERFORM base.cti_add_column_if_not_exists('temp.p_valosej', 'mnt_nn2', 'text');
PERFORM base.cti_add_column_if_not_exists('temp.p_valosej', 'mnt_nn3', 'text');
PERFORM base.cti_add_column_if_not_exists('temp.p_valosej', 'mnt_po1', 'text');
PERFORM base.cti_add_column_if_not_exists('temp.p_valosej', 'mnt_po2', 'text');
PERFORM base.cti_add_column_if_not_exists('temp.p_valosej', 'mnt_po3', 'text');
PERFORM base.cti_add_column_if_not_exists('temp.p_valosej', 'mnt_po4', 'text');
PERFORM base.cti_add_column_if_not_exists('temp.p_valosej', 'mnt_po5', 'text');
PERFORM base.cti_add_column_if_not_exists('temp.p_valosej', 'mnt_po6', 'text');
PERFORM base.cti_add_column_if_not_exists('temp.p_valosej', 'mnt_po7', 'text');
PERFORM base.cti_add_column_if_not_exists('temp.p_valosej', 'mnt_po8', 'text');
PERFORM base.cti_add_column_if_not_exists('temp.p_valosej', 'mnt_po9', 'text');
PERFORM base.cti_add_column_if_not_exists('temp.p_valosej', 'mnt_poa', 'text');
PERFORM base.cti_add_column_if_not_exists('temp.p_valosej', 'mnt_rap', 'text');
PERFORM base.cti_add_column_if_not_exists('temp.p_valosej', 'mnt_rea', 'text');
PERFORM base.cti_add_column_if_not_exists('temp.p_valosej', 'mnt_rep', 'text');
PERFORM base.cti_add_column_if_not_exists('temp.p_valosej', 'mnt_sc', 'text');
PERFORM base.cti_add_column_if_not_exists('temp.p_valosej', 'mnt_sdc', 'text');
PERFORM base.cti_add_column_if_not_exists('temp.p_valosej', 'mnt_sdc_am', 'text');
PERFORM base.cti_add_column_if_not_exists('temp.p_valosej', 'mnt_caisson', 'text');
PERFORM base.cti_add_column_if_not_exists('temp.p_valosej', 'mnt_caisson_am', 'text');
PERFORM base.cti_add_column_if_not_exists('temp.p_valosej', 'mnt_si', 'text');
PERFORM base.cti_add_column_if_not_exists('temp.p_valosej', 'mnt_suppent1', 'text');
PERFORM base.cti_add_column_if_not_exists('temp.p_valosej', 'mnt_suppent2', 'text');
PERFORM base.cti_add_column_if_not_exists('temp.p_valosej', 'mnt_suppent3', 'text');
PERFORM base.cti_add_column_if_not_exists('temp.p_valosej', 'mnt_supphd', 'text');
PERFORM base.cti_add_column_if_not_exists('temp.p_valosej', 'mnt_tot', 'text');
PERFORM base.cti_add_column_if_not_exists('temp.p_valosej', 'nb_sdc', 'text');
PERFORM base.cti_add_column_if_not_exists('temp.p_valosej', 'tmf', 'text');
RAISE NOTICE '% | PREPARATION TABLE DE TRAVAIL', to_char(CURRENT_TIMESTAMP, 'YYYY-MM-DD HH24:MI:ss');
DROP TABLE IF EXISTS w_valosej;
EXECUTE '
DROP TABLE IF EXISTS w_valosej;
CREATE TEMP TABLE w_valosej AS
SELECT
p_valosej.no_rss::bigint as no_rss
,0::bigint AS rss_id
,base.cti_to_date(p_valosej.date_ent) as date_ent
,base.cti_to_date(p_valosej.date_sor) as date_sor
,p_valosej.ghs
,base.cti_to_number(p_valosej.ponder) as ponder
,base.cti_to_number(p_valosej.tmf) as tmf
,base.cti_to_number(p_valosej.mnt_fj2) as mnt_majo
,base.cti_to_number(p_valosej.mnt_9610) as mnt_9610
,base.cti_to_number(p_valosej.mnt_9610_am) as mnt_9610_am
,base.cti_to_number(p_valosej.mnt_9615) as mnt_9615
,base.cti_to_number(p_valosej.mnt_9615_am) as mnt_9615_am
,base.cti_to_number(p_valosej.mnt_9619) as mnt_9619
,base.cti_to_number(p_valosej.mnt_9619_am) as mnt_9619_am
,base.cti_to_number(p_valosej.mnt_9620) as mnt_9620
,base.cti_to_number(p_valosej.mnt_9620_am) as mnt_9620_am
,base.cti_to_number(p_valosej.mnt_9621) as mnt_9621
,base.cti_to_number(p_valosej.mnt_9621_am) as mnt_9621_am
,base.cti_to_number(p_valosej.nb_9622) as nb_9622
,base.cti_to_number(p_valosej.mnt_9622) as mnt_9622
,base.cti_to_number(p_valosej.mnt_9622_am) as mnt_9622_am
,base.cti_to_number(p_valosej.mnt_9623) as mnt_9623
,base.cti_to_number(p_valosej.mnt_9623_am) as mnt_9623_am
,base.cti_to_number(p_valosej.mnt_9625) as mnt_9625
,base.cti_to_number(p_valosej.mnt_9625_am) as mnt_9625_am
,base.cti_to_number(p_valosej.mnt_9631) as mnt_9631
,base.cti_to_number(p_valosej.mnt_9631_am) as mnt_9631_am
,base.cti_to_number(p_valosej.mnt_9632) as mnt_9632
,base.cti_to_number(p_valosej.mnt_9632_am) as mnt_9632_am
,base.cti_to_number(p_valosej.mnt_9633) as mnt_9633
,base.cti_to_number(p_valosej.mnt_9633_am) as mnt_9633_am
,base.cti_to_number(p_valosej.nb_ant) as nb_ant
,base.cti_to_number(p_valosej.mnt_ant) as mnt_ant
,base.cti_to_number(p_valosej.mnt_ant_am) as mnt_ant_am
,base.cti_to_number(p_valosej.mnt_dip) as mnt_dip
,base.cti_to_number(p_valosej.mnt_dip_am) as mnt_dip_am
,base.cti_to_number(p_valosej.mnt_exh) as mnt_exh
,base.cti_to_number(p_valosej.mnt_exh_am) as mnt_exh_am
,0 - base.cti_to_number(p_valosej.nbexb) as nbexb
,base.cti_to_number(p_valosej.mnt_exinf) as mnt_exinf
,base.cti_to_number(p_valosej.mnt_exinf_am) as mnt_exinf_am
,base.cti_to_number(p_valosej.mnt_ghs) as mnt_ghs
,base.cti_to_number(p_valosej.mnt_ghs_am) as mnt_ghs_am
,0 - base.cti_to_number(p_valosej.ghs50) as ghs50
,base.cti_to_number(p_valosej.mnt_ghs50) as mnt_ghs50
,base.cti_to_number(p_valosej.mnt_ghs50_am) as mnt_ghs50_am
,base.cti_to_number(p_valosej.mnt_ivg) as mnt_ivg
,base.cti_to_number(p_valosej.mnt_ivg_am) as mnt_ivg_am
,base.cti_to_number(p_valosej.nb_nn1) as nb_nn1
,base.cti_to_number(p_valosej.mnt_nn1) as mnt_nn1
,base.cti_to_number(p_valosej.mnt_nn1_am) as mnt_nn1_am
,base.cti_to_number(p_valosej.nb_nn2) as nb_nn2
,base.cti_to_number(p_valosej.mnt_nn2) as mnt_nn2
,base.cti_to_number(p_valosej.mnt_nn2_am) as mnt_nn2_am
,base.cti_to_number(p_valosej.nb_nn3) as nb_nn3
,base.cti_to_number(p_valosej.mnt_nn3) as mnt_nn3
,base.cti_to_number(p_valosej.mnt_nn3_am) as mnt_nn3_am
,base.cti_to_number(p_valosej.mnt_rap) as mnt_rap
,base.cti_to_number(p_valosej.mnt_rap_am) as mnt_rap_am
,base.cti_to_number(p_valosej.nbjrea) as nb_rea
,base.cti_to_number(p_valosej.mnt_rea) as mnt_rea
,base.cti_to_number(p_valosej.mnt_rea_am) as mnt_rea_am
,base.cti_to_number(p_valosej.nb_src2) as nb_sc
,base.cti_to_number(p_valosej.mnt_sc) as mnt_sc
,base.cti_to_number(p_valosej.mnt_sc_am) as mnt_sc_am
,base.cti_to_number(p_valosej.nb_stf2) as nb_si
,base.cti_to_number(p_valosej.mnt_si) as mnt_si
,base.cti_to_number(p_valosej.mnt_si_am) as mnt_si_am
,base.cti_to_number(p_valosej.mnt_sdc) as mnt_sdc
,base.cti_to_number(p_valosej.mnt_sdc_am) as mnt_sdc_am
,base.cti_to_number(p_valosej.mnt_caisson) as mnt_caisson
,base.cti_to_number(p_valosej.mnt_caisson_am) as mnt_caisson_am
,base.cti_to_number(p_valosej.mnt_supphd) as mnt_supphd
,base.cti_to_number(p_valosej.mnt_supphd_am) as mnt_supphd_am
,base.cti_to_number(p_valosej.mnt_suppent1) as mnt_suppent1
,base.cti_to_number(p_valosej.mnt_suppent1_am) as mnt_suppent1_am
,base.cti_to_number(p_valosej.mnt_suppent2) as mnt_suppent2
,base.cti_to_number(p_valosej.mnt_suppent2_am) as mnt_suppent2_am
,base.cti_to_number(p_valosej.mnt_suppent3) as mnt_suppent3
,base.cti_to_number(p_valosej.mnt_suppent3_am) as mnt_suppent3_am
,base.cti_to_number(p_valosej.mnt_trans) as mnt_trans
,base.cti_to_number(p_valosej.mnt_trans_am) as mnt_trans_am
,base.cti_to_number(p_valosej.nbexh) as nbexh
,base.cti_to_number(p_valosej.taux2) as taux2
,base.cti_to_number(p_valosej.valo) as valo
,base.cti_to_number(p_valosej.coefp) as coefp
,base.cti_to_number(p_valosej.coefrep) as coefrep
,base.cti_to_number(p_valosej.coeftrans) as coeftrans
,CASE WHEN p_valosej.valo = ''2'' THEN 1 ELSE base.cti_to_number(p_valosej.valo) END AS calc_valo
,0::numeric AS calc_tarif_ghs
,0::numeric AS calc_mnt_ghs1
,0::numeric AS calc_mnt_ghs2
,0::numeric AS calc_mnt_ghs_am
,0::numeric AS gen_mnt_ghs1
,0::numeric AS gen_mnt_ghs2
,0::numeric AS gen_mnt_ghs_am
,0::numeric AS calc_tarif_exh
,0::numeric AS calc_mnt_exh1
,0::numeric AS calc_mnt_exh2
,0::numeric AS calc_mnt_exh_am
,0::numeric AS gen_mnt_exh1
,0::numeric AS gen_mnt_exh2
,0::numeric AS gen_mnt_exh_am
,0::numeric AS calc_tarif_exinf
,0::numeric AS calc_forfait_exinf
,0::numeric AS calc_mnt_exinf1
,0::numeric AS calc_mnt_exinf2
,0::numeric AS calc_mnt_exinf_am
,0::numeric AS gen_mnt_exinf1
,0::numeric AS gen_mnt_exinf2
,0::numeric AS gen_mnt_exinf_am
,0::numeric AS calc_mnt_ghs501
,0::numeric AS calc_mnt_ghs502
,0::numeric AS calc_mnt_ghs50_am
,0::numeric AS gen_mnt_ghs501
,0::numeric AS gen_mnt_ghs502
,0::numeric AS gen_mnt_ghs50_am
,0::numeric AS calc_tarif_ant
,0::numeric AS calc_mnt_ant1
,0::numeric AS calc_mnt_ant2
,0::numeric AS calc_mnt_ant_am
,0::numeric AS gen_mnt_ant1
,0::numeric AS gen_mnt_ant2
,0::numeric AS gen_mnt_ant_am
,0::numeric AS calc_tarif_nn1
,0::numeric AS calc_mnt_nn11
,0::numeric AS calc_mnt_nn12
,0::numeric AS calc_mnt_nn1_am
,0::numeric AS gen_mnt_nn11
,0::numeric AS gen_mnt_nn12
,0::numeric AS gen_mnt_nn1_am
,0::numeric AS calc_tarif_sc
,0::numeric AS calc_mnt_sc1
,0::numeric AS calc_mnt_sc2
,0::numeric AS calc_mnt_sc_am
,0::numeric AS gen_mnt_sc1
,0::numeric AS gen_mnt_sc2
,0::numeric AS gen_mnt_sc_am
,0::numeric AS calc_tarif_si
,0::numeric AS calc_mnt_si1
,0::numeric AS calc_mnt_si2
,0::numeric AS calc_mnt_si_am
,0::numeric AS gen_mnt_si1
,0::numeric AS gen_mnt_si2
,0::numeric AS gen_mnt_si_am,
0::numeric AS calc_tarif_rea
,0::numeric AS calc_mnt_rea1
,0::numeric AS calc_mnt_rea2
,0::numeric AS calc_mnt_rea_am
,0::numeric AS gen_mnt_rea1
,0::numeric AS gen_mnt_rea2
,0::numeric AS gen_mnt_rea_am
FROM
temp.p_valosej
WHERE
base.cti_to_number(p_valosej.no_rss) > 0
;
' USING v_annee;
CREATE INDEX i_w_valocti_1 ON w_valocti USING btree (rss_id);
CREATE INDEX i_w_valocti_2 ON w_valocti USING btree (no_rss);
CREATE INDEX i_w_valosej_2 ON w_valosej USING btree (no_rss);
UPDATE w_valosej
SET rss_id = w_valocti.rss_id
FROM w_valocti
WHERE w_valocti.no_rss = w_valosej.no_rss
;
CREATE INDEX i_w_valosej_1 ON w_valosej USING btree (rss_id);
RAISE NOTICE '% | ARRONDISVALORISATION GHS', to_char(CURRENT_TIMESTAMP, 'YYYY-MM-DD HH24:MI:ss');
-- Recherche tarif
UPDATE w_valosej
SET calc_tarif_ghs =
CASE
WHEN base.cti_to_date(date_sor) >= t_ghs.date_debut_public_1 AND base.cti_to_date(date_sor) <= t_ghs.date_fin_public_1 THEN t_ghs.tarif_ghs_public_1
WHEN base.cti_to_date(date_sor) >= t_ghs.date_debut_public_2 AND base.cti_to_date(date_sor) <= t_ghs.date_fin_public_2 THEN t_ghs.tarif_ghs_public_2
WHEN base.cti_to_date(date_sor) >= t_ghs.date_debut_public_3 AND base.cti_to_date(date_sor) <= t_ghs.date_fin_public_3 THEN t_ghs.tarif_ghs_public_3
WHEN base.cti_to_date(date_sor) >= t_ghs.date_debut_public_4 AND base.cti_to_date(date_sor) <= t_ghs.date_fin_public_4 THEN t_ghs.tarif_ghs_public_4
WHEN base.cti_to_date(date_sor) >= t_ghs.date_debut_public_5 AND base.cti_to_date(date_sor) <= t_ghs.date_fin_public_5 THEN t_ghs.tarif_ghs_public_5
WHEN base.cti_to_date(date_sor) >= t_ghs.date_debut_public_6 AND base.cti_to_date(date_sor) <= t_ghs.date_fin_public_6 THEN t_ghs.tarif_ghs_public_6
WHEN base.cti_to_date(date_sor) >= t_ghs.date_debut_public_7 AND base.cti_to_date(date_sor) <= t_ghs.date_fin_public_7 THEN t_ghs.tarif_ghs_public_7
WHEN base.cti_to_date(date_sor) >= t_ghs.date_debut_public_8 AND base.cti_to_date(date_sor) <= t_ghs.date_fin_public_8 THEN t_ghs.tarif_ghs_public_8
WHEN base.cti_to_date(date_sor) >= t_ghs.date_debut_public_9 AND base.cti_to_date(date_sor) <= t_ghs.date_fin_public_9 THEN t_ghs.tarif_ghs_public_9
ELSE 0::numeric
END,
calc_tarif_exh =
CASE
WHEN base.cti_to_date(date_sor) >= t_ghs.date_debut_public_1 AND base.cti_to_date(date_sor) <= t_ghs.date_fin_public_1 THEN t_ghs.tarif_exh_public_1
WHEN base.cti_to_date(date_sor) >= t_ghs.date_debut_public_2 AND base.cti_to_date(date_sor) <= t_ghs.date_fin_public_2 THEN t_ghs.tarif_exh_public_2
WHEN base.cti_to_date(date_sor) >= t_ghs.date_debut_public_3 AND base.cti_to_date(date_sor) <= t_ghs.date_fin_public_3 THEN t_ghs.tarif_exh_public_3
WHEN base.cti_to_date(date_sor) >= t_ghs.date_debut_public_4 AND base.cti_to_date(date_sor) <= t_ghs.date_fin_public_4 THEN t_ghs.tarif_exh_public_4
WHEN base.cti_to_date(date_sor) >= t_ghs.date_debut_public_5 AND base.cti_to_date(date_sor) <= t_ghs.date_fin_public_5 THEN t_ghs.tarif_exh_public_5
WHEN base.cti_to_date(date_sor) >= t_ghs.date_debut_public_6 AND base.cti_to_date(date_sor) <= t_ghs.date_fin_public_6 THEN t_ghs.tarif_exh_public_6
WHEN base.cti_to_date(date_sor) >= t_ghs.date_debut_public_7 AND base.cti_to_date(date_sor) <= t_ghs.date_fin_public_7 THEN t_ghs.tarif_exh_public_7
WHEN base.cti_to_date(date_sor) >= t_ghs.date_debut_public_8 AND base.cti_to_date(date_sor) <= t_ghs.date_fin_public_8 THEN t_ghs.tarif_exh_public_8
WHEN base.cti_to_date(date_sor) >= t_ghs.date_debut_public_9 AND base.cti_to_date(date_sor) <= t_ghs.date_fin_public_9 THEN t_ghs.tarif_exh_public_9
ELSE 0::numeric
END,
calc_forfait_exinf =
CASE
WHEN base.cti_to_date(date_sor) >= t_ghs.date_debut_public_1 AND base.cti_to_date(date_sor) <= t_ghs.date_fin_public_1 THEN t_ghs.forfait_exb_public_1
WHEN base.cti_to_date(date_sor) >= t_ghs.date_debut_public_2 AND base.cti_to_date(date_sor) <= t_ghs.date_fin_public_2 THEN t_ghs.forfait_exb_public_2
WHEN base.cti_to_date(date_sor) >= t_ghs.date_debut_public_3 AND base.cti_to_date(date_sor) <= t_ghs.date_fin_public_3 THEN t_ghs.forfait_exb_public_3
WHEN base.cti_to_date(date_sor) >= t_ghs.date_debut_public_4 AND base.cti_to_date(date_sor) <= t_ghs.date_fin_public_4 THEN t_ghs.forfait_exb_public_4
WHEN base.cti_to_date(date_sor) >= t_ghs.date_debut_public_5 AND base.cti_to_date(date_sor) <= t_ghs.date_fin_public_5 THEN t_ghs.forfait_exb_public_5
WHEN base.cti_to_date(date_sor) >= t_ghs.date_debut_public_6 AND base.cti_to_date(date_sor) <= t_ghs.date_fin_public_6 THEN t_ghs.forfait_exb_public_6
WHEN base.cti_to_date(date_sor) >= t_ghs.date_debut_public_7 AND base.cti_to_date(date_sor) <= t_ghs.date_fin_public_7 THEN t_ghs.forfait_exb_public_7
WHEN base.cti_to_date(date_sor) >= t_ghs.date_debut_public_8 AND base.cti_to_date(date_sor) <= t_ghs.date_fin_public_8 THEN t_ghs.forfait_exb_public_8
WHEN base.cti_to_date(date_sor) >= t_ghs.date_debut_public_9 AND base.cti_to_date(date_sor) <= t_ghs.date_fin_public_9 THEN t_ghs.forfait_exb_public_9
ELSE 0::numeric
END
,
calc_tarif_exinf =
CASE
WHEN base.cti_to_date(date_sor) >= t_ghs.date_debut_public_1 AND base.cti_to_date(date_sor) <= t_ghs.date_fin_public_1 THEN t_ghs.tarif_exb_public_1
WHEN base.cti_to_date(date_sor) >= t_ghs.date_debut_public_2 AND base.cti_to_date(date_sor) <= t_ghs.date_fin_public_2 THEN t_ghs.tarif_exb_public_2
WHEN base.cti_to_date(date_sor) >= t_ghs.date_debut_public_3 AND base.cti_to_date(date_sor) <= t_ghs.date_fin_public_3 THEN t_ghs.tarif_exb_public_3
WHEN base.cti_to_date(date_sor) >= t_ghs.date_debut_public_4 AND base.cti_to_date(date_sor) <= t_ghs.date_fin_public_4 THEN t_ghs.tarif_exb_public_4
WHEN base.cti_to_date(date_sor) >= t_ghs.date_debut_public_5 AND base.cti_to_date(date_sor) <= t_ghs.date_fin_public_5 THEN t_ghs.tarif_exb_public_5
WHEN base.cti_to_date(date_sor) >= t_ghs.date_debut_public_6 AND base.cti_to_date(date_sor) <= t_ghs.date_fin_public_6 THEN t_ghs.tarif_exb_public_6
WHEN base.cti_to_date(date_sor) >= t_ghs.date_debut_public_7 AND base.cti_to_date(date_sor) <= t_ghs.date_fin_public_7 THEN t_ghs.tarif_exb_public_7
WHEN base.cti_to_date(date_sor) >= t_ghs.date_debut_public_8 AND base.cti_to_date(date_sor) <= t_ghs.date_fin_public_8 THEN t_ghs.tarif_exb_public_8
WHEN base.cti_to_date(date_sor) >= t_ghs.date_debut_public_9 AND base.cti_to_date(date_sor) <= t_ghs.date_fin_public_9 THEN t_ghs.tarif_exb_public_9
ELSE 0::numeric
END
FROM pmsi.t_ghs
WHERE base.cti_to_number(ghs) = t_ghs.code AND
mnt_ghs <> 0 AND
w_valosej.ghs NOT IN ('D11','D24')
;
UPDATE w_valosej
SET calc_tarif_ghs =
CASE
WHEN base.cti_to_date(date_sor) >= t_prestations.date_debut_public_1 AND base.cti_to_date(date_sor) <= t_prestations.date_fin_public_1 THEN t_prestations.tarif_public_1
WHEN base.cti_to_date(date_sor) >= t_prestations.date_debut_public_2 AND base.cti_to_date(date_sor) <= t_prestations.date_fin_public_2 THEN t_prestations.tarif_public_2
WHEN base.cti_to_date(date_sor) >= t_prestations.date_debut_public_3 AND base.cti_to_date(date_sor) <= t_prestations.date_fin_public_3 THEN t_prestations.tarif_public_3
WHEN base.cti_to_date(date_sor) >= t_prestations.date_debut_public_4 AND base.cti_to_date(date_sor) <= t_prestations.date_fin_public_4 THEN t_prestations.tarif_public_4
WHEN base.cti_to_date(date_sor) >= t_prestations.date_debut_public_5 AND base.cti_to_date(date_sor) <= t_prestations.date_fin_public_5 THEN t_prestations.tarif_public_5
WHEN base.cti_to_date(date_sor) >= t_prestations.date_debut_public_6 AND base.cti_to_date(date_sor) <= t_prestations.date_fin_public_6 THEN t_prestations.tarif_public_6
WHEN base.cti_to_date(date_sor) >= t_prestations.date_debut_public_7 AND base.cti_to_date(date_sor) <= t_prestations.date_fin_public_7 THEN t_prestations.tarif_public_7
WHEN base.cti_to_date(date_sor) >= t_prestations.date_debut_public_8 AND base.cti_to_date(date_sor) <= t_prestations.date_fin_public_8 THEN t_prestations.tarif_public_8
WHEN base.cti_to_date(date_sor) >= t_prestations.date_debut_public_9 AND base.cti_to_date(date_sor) <= t_prestations.date_fin_public_9 THEN t_prestations.tarif_public_9
ELSE 0::numeric
END
FROM pmsi.t_prestations
WHERE t_prestations.code = w_valosej.ghs AND
w_valosej.ghs IN ('D11','D24')
;
-- PU ANT
UPDATE w_valosej
SET calc_tarif_ant = pu
FROM
(
SELECT periode, (MAX(ARRAY[nb::numeric,pu]))[2] AS pu
FROM
(
SELECT CASE WHEN date_part('month',date_sor) <= 2 THEN 0 ELSE 1 END AS periode,
pu,
count(*) AS nb
FROM
(
SELECT date_sor, nb_ant, mnt_ant, coefp, coefrep, coeftrans,
round(mnt_ant / coefrep / coeftrans / nb_ant,2) AS pu
FROM w_valosej
WHERE mnt_ant <> 0
) subview
GROUP BY 1,2
) subview
GROUP BY 1
) subview
WHERE mnt_ant <> 0 AND
CASE WHEN date_part('month',date_sor) <= 2 THEN 0 ELSE 1 END = periode
;
-- PU NN1
UPDATE w_valosej
SET calc_tarif_nn1 = pu
FROM
(
SELECT periode, (MAX(ARRAY[nb::numeric,pu]))[2] AS pu
FROM
(
SELECT CASE WHEN date_part('month',date_sor) <= 2 THEN 0 ELSE 1 END AS periode,
pu,
count(*) AS nb
FROM
(
SELECT date_sor, nb_nn1, mnt_nn1, coefp, coefrep, coeftrans,
round(mnt_nn1 / coefrep / coeftrans / nb_nn1,2) AS pu
FROM w_valosej
WHERE mnt_nn1 <> 0
) subview
GROUP BY 1,2
) subview
GROUP BY 1
) subview
WHERE mnt_nn1 <> 0 AND
CASE WHEN date_part('month',date_sor) <= 2 THEN 0 ELSE 1 END = periode
;
-- PU SC
UPDATE w_valosej
SET calc_tarif_sc = pu
FROM
(
SELECT periode, (MAX(ARRAY[nb::numeric,pu]))[2] AS pu
FROM
(
SELECT CASE WHEN date_part('month',date_sor) <= 2 THEN 0 ELSE 1 END AS periode,
pu,
count(*) AS nb
FROM
(
SELECT date_sor, nb_sc, mnt_sc, coefp, coefrep, coeftrans,
round(mnt_sc / coefrep / coeftrans / nb_sc,2) AS pu
FROM w_valosej
WHERE mnt_sc <> 0
) subview
GROUP BY 1,2
) subview
GROUP BY 1
) subview
WHERE mnt_sc <> 0 AND
CASE WHEN date_part('month',date_sor) <= 2 THEN 0 ELSE 1 END = periode
;
-- PU STF
UPDATE w_valosej
SET calc_tarif_si = pu
FROM
(
SELECT periode, (MAX(ARRAY[nb::numeric,pu]))[2] AS pu
FROM
(
SELECT CASE WHEN date_part('month',date_sor) <= 2 THEN 0 ELSE 1 END AS periode,
pu,
count(*) AS nb
FROM
(
SELECT date_sor, nb_si, mnt_si, coefp, coefrep, coeftrans,
round(mnt_si / coefrep / coeftrans / nb_si,2) AS pu
FROM w_valosej
WHERE mnt_si <> 0
) subview
GROUP BY 1,2
) subview
GROUP BY 1
) subview
WHERE mnt_si <> 0 AND
CASE WHEN date_part('month',date_sor) <= 2 THEN 0 ELSE 1 END = periode
;
-- PU REA
UPDATE w_valosej
SET calc_tarif_rea = pu
FROM
(
SELECT periode, (MAX(ARRAY[nb::numeric,pu]))[2] AS pu
FROM
(
SELECT CASE WHEN date_part('month',date_sor) <= 2 THEN 0 ELSE 1 END AS periode,
pu,
count(*) AS nb
FROM
(
SELECT date_sor, nb_rea, mnt_rea, coefp, coefrep, coeftrans,
round(mnt_rea / coefrep / coeftrans / nb_rea,2) AS pu
FROM w_valosej
WHERE mnt_rea <> 0
) subview
GROUP BY 1,2
) subview
GROUP BY 1
) subview
WHERE mnt_rea <> 0 AND
CASE WHEN date_part('month',date_sor) <= 2 THEN 0 ELSE 1 END = periode
;
-- Recalcul montants sans arrondis
UPDATE w_valosej SET
calc_mnt_ghs1 = calc_tarif_ghs * ponder * coeftrans * coefrep * coefp,
calc_mnt_ghs2 = calc_tarif_ghs * ponder * coeftrans * coefrep,
calc_mnt_exh1 = calc_tarif_exh * nbexh * coeftrans * coefrep * coefp,
calc_mnt_exh2 = calc_tarif_exh * nbexh * coeftrans * coefrep,
calc_mnt_exinf1 = calc_tarif_exinf * nbexb * coeftrans * coefrep * coefp,
calc_mnt_exinf2 = calc_tarif_exinf * nbexb * coeftrans * coefrep,
calc_mnt_ghs501 = CASE WHEN ghs50 < 0 THEN ((calc_tarif_ghs * ghs50 * coeftrans * coefrep * coefp) - (calc_tarif_exinf * nbexb * coeftrans * coefrep * coefp)) / 2 ELSE 0 END,
calc_mnt_ghs502 = CASE WHEN ghs50 < 0 THEN ((calc_tarif_ghs * ghs50 * coeftrans * coefrep) - (calc_tarif_exinf * nbexb * coeftrans * coefrep)) / 2 ELSE 0 END,
calc_mnt_ant1 = calc_tarif_ant * nb_ant * coeftrans * coefrep * coefp,
calc_mnt_ant2 = calc_tarif_ant * nb_ant * coeftrans * coefrep,
calc_mnt_nn11 = calc_tarif_nn1 * nb_nn1 * coeftrans * coefrep * coefp,
calc_mnt_nn12 = calc_tarif_nn1 * nb_nn1 * coeftrans * coefrep,
calc_mnt_sc1 = calc_tarif_sc * nb_sc * coeftrans * coefrep * coefp,
calc_mnt_sc2 = calc_tarif_sc * nb_sc * coeftrans * coefrep,
calc_mnt_si1 = calc_tarif_si * nb_si * coeftrans * coefrep * coefp,
calc_mnt_si2 = calc_tarif_si * nb_si * coeftrans * coefrep,
calc_mnt_rea1 = calc_tarif_rea * nb_rea * coeftrans * coefrep * coefp,
calc_mnt_rea2 = calc_tarif_rea * nb_rea * coeftrans * coefrep
;
UPDATE w_valosej SET
taux2 = 100
WHERE mnt_majo > 0 AND
taux2 <> 100 AND
ABS((CASE WHEN valo NOT IN (3,4) THEN calc_mnt_ghs1 ELSE calc_mnt_ghs2 END) - tmf-mnt_majo - mnt_ghs_am) <= 1
;
UPDATE w_valosej SET
calc_mnt_ghs_am = (CASE WHEN valo NOT IN (3,4) THEN calc_mnt_ghs1 ELSE calc_mnt_ghs2 END * taux2 / 100)-tmf-mnt_majo,
calc_mnt_exh_am = (CASE WHEN valo NOT IN (3,4) THEN calc_mnt_exh1 ELSE calc_mnt_exh2 END * taux2 / 100),
calc_mnt_exinf_am = (CASE WHEN valo NOT IN (3,4) THEN calc_mnt_exinf1 ELSE calc_mnt_exinf2 END * taux2 / 100),
calc_mnt_ghs50_am = (CASE WHEN valo NOT IN (3,4) THEN calc_mnt_ghs501 ELSE calc_mnt_ghs502 END * taux2 / 100),
calc_mnt_ant_am = (CASE WHEN valo NOT IN (3,4) THEN calc_mnt_ant1 ELSE calc_mnt_ant2 END * taux2 / 100),
calc_mnt_nn1_am = (CASE WHEN valo NOT IN (3,4) THEN calc_mnt_nn11 ELSE calc_mnt_nn12 END * taux2 / 100),
calc_mnt_sc_am = (CASE WHEN valo NOT IN (3,4) THEN calc_mnt_sc1 ELSE calc_mnt_sc2 END * taux2 / 100),
calc_mnt_si_am = (CASE WHEN valo NOT IN (3,4) THEN calc_mnt_si1 ELSE calc_mnt_si2 END * taux2 / 100),
calc_mnt_rea_am = (CASE WHEN valo NOT IN (3,4) THEN calc_mnt_rea1 ELSE calc_mnt_rea2 END * taux2 / 100)
WHERE valo <> 5
;
UPDATE w_valosej SET
calc_mnt_ghs_am = mnt_ghs_am,
calc_mnt_exh_am = mnt_exh_am,
calc_mnt_exinf_am = mnt_exinf_am,
calc_mnt_ghs50_am = mnt_ghs50_am,
calc_mnt_ant_am = mnt_ant_am,
calc_mnt_nn1_am = mnt_nn1_am,
calc_mnt_sc_am = mnt_sc_am,
calc_mnt_si_am = mnt_si_am,
calc_mnt_rea_am = mnt_rea_am
WHERE valo = 5
;
UPDATE w_valosej SET
calc_mnt_exh_am = mnt_exh_am
WHERE abs(calc_mnt_exh_am-mnt_exh_am) > 1
;
-- Ventilation arrondi GHS par ghs avec 1 centime par dossier
UPDATE w_valosej SET
gen_mnt_ghs1 = round(calc_mnt_ghs1 + ecart_br1,2),
gen_mnt_ghs2 = round(calc_mnt_ghs2 + ecart_br2,2),
gen_mnt_ghs_am = round(calc_mnt_ghs_am + ecart_remb,2)
FROM
(
SELECT w_valosej.rss_id,
row_number() OVER (PARTITION BY w_valosej.ghs, w_valosej.coefrep, w_valosej.coeftrans, w_valosej.calc_valo ORDER BY no_rss),
CASE WHEN row_number() OVER (PARTITION BY w_valosej.ghs, w_valosej.coefrep, w_valosej.coeftrans, w_valosej.calc_valo ORDER BY no_rss) <= nb_ecart_br1 THEN ecart_br1 ELSE 0 END AS ecart_br1,
CASE WHEN row_number() OVER (PARTITION BY w_valosej.ghs, w_valosej.coefrep, w_valosej.coeftrans, w_valosej.calc_valo ORDER BY no_rss) <= nb_ecart_br2 THEN ecart_br2 ELSE 0 END AS ecart_br2,
CASE WHEN row_number() OVER (PARTITION BY w_valosej.ghs, w_valosej.coefrep, w_valosej.coeftrans, w_valosej.calc_valo ORDER BY no_rss) <= nb_ecart_remb THEN ecart_remb ELSE 0 END AS ecart_remb
FROM w_valosej
JOIN
(
SELECT ghs, coefrep, coeftrans, calc_valo,
CASE WHEN round((SUM(calc_mnt_ghs1) - SUM(round(w_valosej.calc_mnt_ghs1,2)))*100,0) >= 0 THEN 0.01 ELSE -0.01 END AS ecart_br1,
CASE WHEN round((SUM(calc_mnt_ghs2) - SUM(round(w_valosej.calc_mnt_ghs2,2)))*100,0) >= 0 THEN 0.01 ELSE -0.01 END AS ecart_br2,
CASE WHEN round((SUM(calc_mnt_ghs_am) - SUM(round(w_valosej.calc_mnt_ghs_am,2)))*100,0) >= 0 THEN 0.01 ELSE -0.01 END AS ecart_remb,
abs(round((SUM(calc_mnt_ghs1) - SUM(round(w_valosej.calc_mnt_ghs1,2)))*100,0)) AS nb_ecart_br1,
abs(round((SUM(calc_mnt_ghs2) - SUM(round(w_valosej.calc_mnt_ghs2,2)))*100,0)) AS nb_ecart_br2,
abs(round((SUM(calc_mnt_ghs_am) - SUM(round(w_valosej.calc_mnt_ghs_am,2)))*100,0)) AS nb_ecart_remb
FROM w_valosej
WHERE (calc_mnt_ghs2 <> 0 OR calc_mnt_ghs_am <> 0)
GROUP BY 1,2,3,4
) subview ON
w_valosej.ghs = subview.ghs AND
w_valosej.coefrep = subview.coefrep AND
w_valosej.coeftrans = subview.coeftrans AND
w_valosej.calc_valo = subview.calc_valo AND
(calc_mnt_ghs2 <> 0 OR calc_mnt_ghs_am <> 0)
ORDER BY no_rss
) subview
WHERE w_valosej.rss_id = subview.rss_id
;
-- Ventilation arrondi GHS sur total avec 1 centime ghs
UPDATE w_valosej SET
gen_mnt_ghs1 = gen_mnt_ghs1 + ecart_br1,
gen_mnt_ghs2 = gen_mnt_ghs2 + ecart_br2,
gen_mnt_ghs_am = gen_mnt_ghs_am + ecart_remb
FROM
(
SELECT subview1.rss_id, row_number() OVER (PARTITION BY subview1.calc_valo ORDER BY subview1.nb DESC),
CASE WHEN row_number() OVER (PARTITION BY subview1.calc_valo ORDER BY subview1.nb DESC) <= nb_ecart_br1 THEN ecart_br1 ELSE 0 END AS ecart_br1,
CASE WHEN row_number() OVER (PARTITION BY subview1.calc_valo ORDER BY subview1.nb DESC) <= nb_ecart_br2 THEN ecart_br2 ELSE 0 END AS ecart_br2,
CASE WHEN row_number() OVER (PARTITION BY subview1.calc_valo ORDER BY subview1.nb DESC) <= nb_ecart_remb THEN ecart_remb ELSE 0 END AS ecart_remb
FROM
(
SELECT calc_valo, ghs, MAX(rss_id) AS rss_id, count(*) AS nb
FROM w_valosej
WHERE (gen_mnt_ghs2 <> 0 OR gen_mnt_ghs_am <> 0)
GROUP BY 1,2
) subview1
JOIN
(
SELECT calc_valo,
CASE WHEN round((SUM(calc_mnt_ghs1) - SUM(w_valosej.gen_mnt_ghs1))*100,0) >= 0 THEN 0.01 ELSE -0.01 END AS ecart_br1,
CASE WHEN round((SUM(calc_mnt_ghs2) - SUM(w_valosej.gen_mnt_ghs2))*100,0) >= 0 THEN 0.01 ELSE -0.01 END AS ecart_br2,
CASE WHEN round((SUM(calc_mnt_ghs_am) - SUM(w_valosej.gen_mnt_ghs_am))*100,0) >= 0 THEN 0.01 ELSE -0.01 END AS ecart_remb,
abs(round((SUM(calc_mnt_ghs1) - SUM(w_valosej.gen_mnt_ghs1))*100,0)) AS nb_ecart_br1,
abs(round((SUM(calc_mnt_ghs2) - SUM(w_valosej.gen_mnt_ghs2))*100,0)) AS nb_ecart_br2,
abs(round((SUM(calc_mnt_ghs_am) - SUM(w_valosej.gen_mnt_ghs_am))*100,0)) AS nb_ecart_remb
FROM w_valosej
WHERE (gen_mnt_ghs2 <> 0 OR gen_mnt_ghs_am <> 0)
GROUP BY 1
) subview2 ON subview1.calc_valo = subview2.calc_valo
ORDER BY subview1.rss_id
) subview
WHERE w_valosej.rss_id = subview.rss_id AND
(
ecart_br2 <> 0 OR
ecart_remb <> 0
)
;
-- Ventilation arrondi EXH par ghs avec 1 centime par dossier
UPDATE w_valosej SET
gen_mnt_exh1 = round(calc_mnt_exh1 + ecart_br1,2),
gen_mnt_exh2 = round(calc_mnt_exh2 + ecart_br2,2),
gen_mnt_exh_am = round(calc_mnt_exh_am + ecart_remb,2)
FROM
(
SELECT w_valosej.rss_id,
row_number() OVER (PARTITION BY w_valosej.ghs, w_valosej.coefrep, w_valosej.coeftrans, w_valosej.calc_valo ORDER BY rss_id),
CASE WHEN row_number() OVER (PARTITION BY w_valosej.ghs, w_valosej.coefrep, w_valosej.coeftrans, w_valosej.calc_valo ORDER BY rss_id) <= nb_ecart_br1 THEN ecart_br1 ELSE 0 END AS ecart_br1,
CASE WHEN row_number() OVER (PARTITION BY w_valosej.ghs, w_valosej.coefrep, w_valosej.coeftrans, w_valosej.calc_valo ORDER BY rss_id) <= nb_ecart_br2 THEN ecart_br2 ELSE 0 END AS ecart_br2,
CASE WHEN row_number() OVER (PARTITION BY w_valosej.ghs, w_valosej.coefrep, w_valosej.coeftrans, w_valosej.calc_valo ORDER BY rss_id) <= nb_ecart_remb THEN ecart_remb ELSE 0 END AS ecart_remb
FROM w_valosej
JOIN
(
SELECT ghs, coefrep, coeftrans, calc_valo,
CASE WHEN round((SUM(calc_mnt_exh1) - SUM(round(w_valosej.calc_mnt_exh1,2)))*100,0) >= 0 THEN 0.01 ELSE -0.01 END AS ecart_br1,
CASE WHEN round((SUM(calc_mnt_exh2) - SUM(round(w_valosej.calc_mnt_exh2,2)))*100,0) >= 0 THEN 0.01 ELSE -0.01 END AS ecart_br2,
CASE WHEN round((SUM(calc_mnt_exh_am) - SUM(round(w_valosej.calc_mnt_exh_am,2)))*100,0) >= 0 THEN 0.01 ELSE -0.01 END AS ecart_remb,
abs(round((SUM(calc_mnt_exh1) - SUM(round(w_valosej.calc_mnt_exh1,2)))*100,0)) AS nb_ecart_br1,
abs(round((SUM(calc_mnt_exh2) - SUM(round(w_valosej.calc_mnt_exh2,2)))*100,0)) AS nb_ecart_br2,
abs(round((SUM(calc_mnt_exh_am) - SUM(round(w_valosej.calc_mnt_exh_am,2)))*100,0)) AS nb_ecart_remb
FROM w_valosej
WHERE (calc_mnt_exh2 <> 0 OR calc_mnt_exh_am <> 0)
GROUP BY 1,2,3,4
) subview ON
w_valosej.ghs = subview.ghs AND
w_valosej.coefrep = subview.coefrep AND
w_valosej.coeftrans = subview.coeftrans AND
w_valosej.calc_valo = subview.calc_valo AND
(calc_mnt_exh2 <> 0 OR calc_mnt_exh_am <> 0)
ORDER BY rss_id
) subview
WHERE w_valosej.rss_id = subview.rss_id
;
-- Ventilation arrondi EXH sur total avec 1 centime ghs
UPDATE w_valosej SET
gen_mnt_exh1 = gen_mnt_exh1 + ecart_br1,
gen_mnt_exh2 = gen_mnt_exh2 + ecart_br2,
gen_mnt_exh_am = gen_mnt_exh_am + ecart_remb
FROM
(
SELECT subview1.rss_id, row_number() OVER (PARTITION BY subview1.calc_valo ORDER BY subview1.nb DESC),
CASE WHEN row_number() OVER (PARTITION BY subview1.calc_valo ORDER BY subview1.nb DESC) <= nb_ecart_br1 THEN ecart_br1 ELSE 0 END AS ecart_br1,
CASE WHEN row_number() OVER (PARTITION BY subview1.calc_valo ORDER BY subview1.nb DESC) <= nb_ecart_br2 THEN ecart_br2 ELSE 0 END AS ecart_br2,
CASE WHEN row_number() OVER (PARTITION BY subview1.calc_valo ORDER BY subview1.nb DESC) <= nb_ecart_remb THEN ecart_remb ELSE 0 END AS ecart_remb
FROM
(
SELECT calc_valo, ghs, MAX(rss_id) AS rss_id, count(*) AS nb
FROM w_valosej
WHERE (gen_mnt_exh2 <> 0 OR gen_mnt_exh_am <> 0)
GROUP BY 1,2
) subview1
JOIN
(
SELECT calc_valo,
CASE WHEN round((SUM(calc_mnt_exh1) - SUM(w_valosej.gen_mnt_exh1))*100,0) >= 0 THEN 0.01 ELSE -0.01 END AS ecart_br1,
CASE WHEN round((SUM(calc_mnt_exh2) - SUM(w_valosej.gen_mnt_exh2))*100,0) >= 0 THEN 0.01 ELSE -0.01 END AS ecart_br2,
CASE WHEN round((SUM(calc_mnt_exh_am) - SUM(w_valosej.gen_mnt_exh_am))*100,0) >= 0 THEN 0.01 ELSE -0.01 END AS ecart_remb,
abs(round((SUM(calc_mnt_exh1) - SUM(w_valosej.gen_mnt_exh1))*100,0)) AS nb_ecart_br1,
abs(round((SUM(calc_mnt_exh2) - SUM(w_valosej.gen_mnt_exh2))*100,0)) AS nb_ecart_br2,
abs(round((SUM(calc_mnt_exh_am) - SUM(w_valosej.gen_mnt_exh_am))*100,0)) AS nb_ecart_remb
FROM w_valosej
WHERE (gen_mnt_exh2 <> 0 OR gen_mnt_exh_am <> 0)
GROUP BY 1
) subview2 ON subview1.calc_valo = subview2.calc_valo
ORDER BY rss_id
) subview
WHERE w_valosej.rss_id = subview.rss_id AND
(
ecart_br2 <> 0 OR
ecart_remb <> 0
)
;
-- Ventilation arrondi EXB par ghs avec 1 centime par dossier
UPDATE w_valosej SET
gen_mnt_exinf1 = round(calc_mnt_exinf1 + ecart_br1,2),
gen_mnt_exinf2 = round(calc_mnt_exinf2 + ecart_br2,2),
gen_mnt_exinf_am = round(calc_mnt_exinf_am + ecart_remb,2)
FROM
(
SELECT w_valosej.rss_id,
row_number() OVER (PARTITION BY w_valosej.ghs, w_valosej.coefrep, w_valosej.coeftrans, w_valosej.calc_valo ORDER BY rss_id),
CASE WHEN row_number() OVER (PARTITION BY w_valosej.ghs, w_valosej.coefrep, w_valosej.coeftrans, w_valosej.calc_valo ORDER BY rss_id) <= nb_ecart_br1 THEN ecart_br1 ELSE 0 END AS ecart_br1,
CASE WHEN row_number() OVER (PARTITION BY w_valosej.ghs, w_valosej.coefrep, w_valosej.coeftrans, w_valosej.calc_valo ORDER BY rss_id) <= nb_ecart_br2 THEN ecart_br2 ELSE 0 END AS ecart_br2,
CASE WHEN row_number() OVER (PARTITION BY w_valosej.ghs, w_valosej.coefrep, w_valosej.coeftrans, w_valosej.calc_valo ORDER BY rss_id) <= nb_ecart_remb THEN ecart_remb ELSE 0 END AS ecart_remb
FROM w_valosej
JOIN
(
SELECT ghs, coefrep, coeftrans, calc_valo,
CASE WHEN round((SUM(calc_mnt_exinf1) - SUM(round(w_valosej.calc_mnt_exinf1,2)))*100,0) >= 0 THEN 0.01 ELSE -0.01 END AS ecart_br1,
CASE WHEN round((SUM(calc_mnt_exinf2) - SUM(round(w_valosej.calc_mnt_exinf2,2)))*100,0) >= 0 THEN 0.01 ELSE -0.01 END AS ecart_br2,
CASE WHEN round((SUM(calc_mnt_exinf_am) - SUM(round(w_valosej.calc_mnt_exinf_am,2)))*100,0) >= 0 THEN 0.01 ELSE -0.01 END AS ecart_remb,
abs(round((SUM(calc_mnt_exinf1) - SUM(round(w_valosej.calc_mnt_exinf1,2)))*100,0)) AS nb_ecart_br1,
abs(round((SUM(calc_mnt_exinf2) - SUM(round(w_valosej.calc_mnt_exinf2,2)))*100,0)) AS nb_ecart_br2,
abs(round((SUM(calc_mnt_exinf_am) - SUM(round(w_valosej.calc_mnt_exinf_am,2)))*100,0)) AS nb_ecart_remb
FROM w_valosej
WHERE (calc_mnt_exinf2 <> 0 OR calc_mnt_exinf_am <> 0)
GROUP BY 1,2,3,4
) subview ON
w_valosej.ghs = subview.ghs AND
w_valosej.coefrep = subview.coefrep AND
w_valosej.coeftrans = subview.coeftrans AND
w_valosej.calc_valo = subview.calc_valo AND
(calc_mnt_exinf2 <> 0 OR calc_mnt_exinf_am <> 0)
ORDER BY rss_id
) subview
WHERE w_valosej.rss_id = subview.rss_id
;
-- Ventilation arrondi EXB sur total avec 1 centime ghs
UPDATE w_valosej SET
gen_mnt_exinf1 = gen_mnt_exinf1 + ecart_br1,
gen_mnt_exinf2 = gen_mnt_exinf2 + ecart_br2,
gen_mnt_exinf_am = gen_mnt_exinf_am + ecart_remb
FROM
(
SELECT subview1.rss_id, row_number() OVER (PARTITION BY subview1.calc_valo ORDER BY subview1.nb DESC),
CASE WHEN row_number() OVER (PARTITION BY subview1.calc_valo ORDER BY subview1.nb DESC) <= nb_ecart_br1 THEN ecart_br1 ELSE 0 END AS ecart_br1,
CASE WHEN row_number() OVER (PARTITION BY subview1.calc_valo ORDER BY subview1.nb DESC) <= nb_ecart_br2 THEN ecart_br2 ELSE 0 END AS ecart_br2,
CASE WHEN row_number() OVER (PARTITION BY subview1.calc_valo ORDER BY subview1.nb DESC) <= nb_ecart_remb THEN ecart_remb ELSE 0 END AS ecart_remb
FROM
(
SELECT calc_valo, ghs, MAX(rss_id) AS rss_id, count(*) AS nb
FROM w_valosej
WHERE (gen_mnt_exinf2 <> 0 OR gen_mnt_exinf_am <> 0)
GROUP BY 1,2
) subview1
JOIN
(
SELECT calc_valo,
CASE WHEN round((SUM(calc_mnt_exinf1) - SUM(w_valosej.gen_mnt_exinf1))*100,0) >= 0 THEN 0.01 ELSE -0.01 END AS ecart_br1,
CASE WHEN round((SUM(calc_mnt_exinf2) - SUM(w_valosej.gen_mnt_exinf2))*100,0) >= 0 THEN 0.01 ELSE -0.01 END AS ecart_br2,
CASE WHEN round((SUM(calc_mnt_exinf_am) - SUM(w_valosej.gen_mnt_exinf_am))*100,0) >= 0 THEN 0.01 ELSE -0.01 END AS ecart_remb,
abs(round((SUM(calc_mnt_exinf1) - SUM(w_valosej.gen_mnt_exinf1))*100,0)) AS nb_ecart_br1,
abs(round((SUM(calc_mnt_exinf2) - SUM(w_valosej.gen_mnt_exinf2))*100,0)) AS nb_ecart_br2,
abs(round((SUM(calc_mnt_exinf_am) - SUM(w_valosej.gen_mnt_exinf_am))*100,0)) AS nb_ecart_remb
FROM w_valosej
WHERE (gen_mnt_exinf2 <> 0 OR gen_mnt_exinf_am <> 0)
GROUP BY 1
) subview2 ON subview1.calc_valo = subview2.calc_valo
ORDER BY rss_id
) subview
WHERE w_valosej.rss_id = subview.rss_id AND
(
ecart_br2 <> 0 OR
ecart_remb <> 0
)
;
-- Ventilation arrondi REHOSP par ghs avec 1 centime par dossier
UPDATE w_valosej SET
gen_mnt_ghs501 = round(calc_mnt_ghs501 + ecart_br1,2),
gen_mnt_ghs502 = round(calc_mnt_ghs502 + ecart_br2,2),
gen_mnt_ghs50_am = round(calc_mnt_ghs50_am + ecart_remb,2)
FROM
(
SELECT w_valosej.rss_id,
row_number() OVER (PARTITION BY w_valosej.ghs, w_valosej.coefrep, w_valosej.coeftrans, w_valosej.calc_valo ORDER BY rss_id),
CASE WHEN row_number() OVER (PARTITION BY w_valosej.ghs, w_valosej.coefrep, w_valosej.coeftrans, w_valosej.calc_valo ORDER BY rss_id) <= nb_ecart_br1 THEN ecart_br1 ELSE 0 END AS ecart_br1,
CASE WHEN row_number() OVER (PARTITION BY w_valosej.ghs, w_valosej.coefrep, w_valosej.coeftrans, w_valosej.calc_valo ORDER BY rss_id) <= nb_ecart_br2 THEN ecart_br2 ELSE 0 END AS ecart_br2,
CASE WHEN row_number() OVER (PARTITION BY w_valosej.ghs, w_valosej.coefrep, w_valosej.coeftrans, w_valosej.calc_valo ORDER BY rss_id) <= nb_ecart_remb THEN ecart_remb ELSE 0 END AS ecart_remb
FROM w_valosej
JOIN
(
SELECT ghs, coefrep, coeftrans, calc_valo,
CASE WHEN round((SUM(calc_mnt_ghs501) - SUM(round(w_valosej.calc_mnt_ghs501,2)))*100,0) >= 0 THEN 0.01 ELSE -0.01 END AS ecart_br1,
CASE WHEN round((SUM(calc_mnt_ghs502) - SUM(round(w_valosej.calc_mnt_ghs502,2)))*100,0) >= 0 THEN 0.01 ELSE -0.01 END AS ecart_br2,
CASE WHEN round((SUM(calc_mnt_ghs50_am) - SUM(round(w_valosej.calc_mnt_ghs50_am,2)))*100,0) >= 0 THEN 0.01 ELSE -0.01 END AS ecart_remb,
abs(round((SUM(calc_mnt_ghs501) - SUM(round(w_valosej.calc_mnt_ghs501,2)))*100,0)) AS nb_ecart_br1,
abs(round((SUM(calc_mnt_ghs502) - SUM(round(w_valosej.calc_mnt_ghs502,2)))*100,0)) AS nb_ecart_br2,
abs(round((SUM(calc_mnt_ghs50_am) - SUM(round(w_valosej.calc_mnt_ghs50_am,2)))*100,0)) AS nb_ecart_remb
FROM w_valosej
WHERE (calc_mnt_ghs502 <> 0 OR calc_mnt_ghs50_am <> 0)
GROUP BY 1,2,3,4
) subview ON
w_valosej.ghs = subview.ghs AND
w_valosej.coefrep = subview.coefrep AND
w_valosej.coeftrans = subview.coeftrans AND
w_valosej.calc_valo = subview.calc_valo AND
(calc_mnt_ghs502 <> 0 OR calc_mnt_ghs50_am <> 0)
ORDER BY rss_id
) subview
WHERE w_valosej.rss_id = subview.rss_id
;
-- Ventilation arrondi REHOSP sur total avec 1 centime ghs
UPDATE w_valosej SET
gen_mnt_ghs501 = gen_mnt_ghs501 + ecart_br1,
gen_mnt_ghs502 = gen_mnt_ghs502 + ecart_br2,
gen_mnt_ghs50_am = gen_mnt_ghs50_am + ecart_remb
FROM
(
SELECT subview1.rss_id, row_number() OVER (PARTITION BY subview1.calc_valo ORDER BY subview1.nb DESC),
CASE WHEN row_number() OVER (PARTITION BY subview1.calc_valo ORDER BY subview1.nb DESC) <= nb_ecart_br1 THEN ecart_br1 ELSE 0 END AS ecart_br1,
CASE WHEN row_number() OVER (PARTITION BY subview1.calc_valo ORDER BY subview1.nb DESC) <= nb_ecart_br2 THEN ecart_br2 ELSE 0 END AS ecart_br2,
CASE WHEN row_number() OVER (PARTITION BY subview1.calc_valo ORDER BY subview1.nb DESC) <= nb_ecart_remb THEN ecart_remb ELSE 0 END AS ecart_remb
FROM
(
SELECT calc_valo, ghs, MAX(rss_id) AS rss_id, count(*) AS nb
FROM w_valosej
WHERE (gen_mnt_ghs502 <> 0 OR gen_mnt_ghs50_am <> 0)
GROUP BY 1,2
) subview1
JOIN
(
SELECT calc_valo,
CASE WHEN round((SUM(calc_mnt_ghs501) - SUM(w_valosej.gen_mnt_ghs501))*100,0) >= 0 THEN 0.01 ELSE -0.01 END AS ecart_br1,
CASE WHEN round((SUM(calc_mnt_ghs502) - SUM(w_valosej.gen_mnt_ghs502))*100,0) >= 0 THEN 0.01 ELSE -0.01 END AS ecart_br2,
CASE WHEN round((SUM(calc_mnt_ghs50_am) - SUM(w_valosej.gen_mnt_ghs50_am))*100,0) >= 0 THEN 0.01 ELSE -0.01 END AS ecart_remb,
abs(round((SUM(calc_mnt_ghs501) - SUM(w_valosej.gen_mnt_ghs501))*100,0)) AS nb_ecart_br1,
abs(round((SUM(calc_mnt_ghs502) - SUM(w_valosej.gen_mnt_ghs502))*100,0)) AS nb_ecart_br2,
abs(round((SUM(calc_mnt_ghs50_am) - SUM(w_valosej.gen_mnt_ghs50_am))*100,0)) AS nb_ecart_remb
FROM w_valosej
WHERE (gen_mnt_ghs502 <> 0 OR gen_mnt_ghs50_am <> 0)
GROUP BY 1
) subview2 ON subview1.calc_valo = subview2.calc_valo
ORDER BY rss_id
) subview
WHERE w_valosej.rss_id = subview.rss_id AND
(
ecart_br2 <> 0 OR
ecart_remb <> 0
)
;
-- Ventilation arrondi ANT par ghs avec 1 centime par dossier
UPDATE w_valosej SET
gen_mnt_ant1 = round(calc_mnt_ant1 + ecart_br1,2),
gen_mnt_ant2 = round(calc_mnt_ant2 + ecart_br2,2),
gen_mnt_ant_am = round(calc_mnt_ant_am + ecart_remb,2)
FROM
(
SELECT w_valosej.rss_id,
row_number() OVER (PARTITION BY w_valosej.ghs, w_valosej.coefrep, w_valosej.coeftrans, w_valosej.calc_valo ORDER BY rss_id),
CASE WHEN row_number() OVER (PARTITION BY w_valosej.ghs, w_valosej.coefrep, w_valosej.coeftrans, w_valosej.calc_valo ORDER BY rss_id) <= nb_ecart_br1 THEN ecart_br1 ELSE 0 END AS ecart_br1,
CASE WHEN row_number() OVER (PARTITION BY w_valosej.ghs, w_valosej.coefrep, w_valosej.coeftrans, w_valosej.calc_valo ORDER BY rss_id) <= nb_ecart_br2 THEN ecart_br2 ELSE 0 END AS ecart_br2,
CASE WHEN row_number() OVER (PARTITION BY w_valosej.ghs, w_valosej.coefrep, w_valosej.coeftrans, w_valosej.calc_valo ORDER BY rss_id) <= nb_ecart_remb THEN ecart_remb ELSE 0 END AS ecart_remb
FROM w_valosej
JOIN
(
SELECT ghs, coefrep, coeftrans, calc_valo,
CASE WHEN round((SUM(calc_mnt_ant1) - SUM(round(w_valosej.calc_mnt_ant1,2)))*100,0) >= 0 THEN 0.01 ELSE -0.01 END AS ecart_br1,
CASE WHEN round((SUM(calc_mnt_ant2) - SUM(round(w_valosej.calc_mnt_ant2,2)))*100,0) >= 0 THEN 0.01 ELSE -0.01 END AS ecart_br2,
CASE WHEN round((SUM(calc_mnt_ant_am) - SUM(round(w_valosej.calc_mnt_ant_am,2)))*100,0) >= 0 THEN 0.01 ELSE -0.01 END AS ecart_remb,
abs(round((SUM(calc_mnt_ant1) - SUM(round(w_valosej.calc_mnt_ant1,2)))*100,0)) AS nb_ecart_br1,
abs(round((SUM(calc_mnt_ant2) - SUM(round(w_valosej.calc_mnt_ant2,2)))*100,0)) AS nb_ecart_br2,
abs(round((SUM(calc_mnt_ant_am) - SUM(round(w_valosej.calc_mnt_ant_am,2)))*100,0)) AS nb_ecart_remb
FROM w_valosej
WHERE (calc_mnt_ant2 <> 0 OR calc_mnt_ant_am <> 0)
GROUP BY 1,2,3,4
) subview ON
w_valosej.ghs = subview.ghs AND
w_valosej.coefrep = subview.coefrep AND
w_valosej.coeftrans = subview.coeftrans AND
w_valosej.calc_valo = subview.calc_valo AND
(calc_mnt_ant2 <> 0 OR calc_mnt_ant_am <> 0)
ORDER BY rss_id
) subview
WHERE w_valosej.rss_id = subview.rss_id
;
-- Ventilation arrondi AND sur total avec 1 centime ghs
UPDATE w_valosej SET
gen_mnt_ant1 = gen_mnt_ant1 + ecart_br1,
gen_mnt_ant2 = gen_mnt_ant2 + ecart_br2,
gen_mnt_ant_am = gen_mnt_ant_am + ecart_remb
FROM
(
SELECT subview1.rss_id, row_number() OVER (PARTITION BY subview1.calc_valo ORDER BY subview1.nb DESC),
CASE WHEN row_number() OVER (PARTITION BY subview1.calc_valo ORDER BY subview1.nb DESC) <= nb_ecart_br1 THEN ecart_br1 ELSE 0 END AS ecart_br1,
CASE WHEN row_number() OVER (PARTITION BY subview1.calc_valo ORDER BY subview1.nb DESC) <= nb_ecart_br2 THEN ecart_br2 ELSE 0 END AS ecart_br2,
CASE WHEN row_number() OVER (PARTITION BY subview1.calc_valo ORDER BY subview1.nb DESC) <= nb_ecart_remb THEN ecart_remb ELSE 0 END AS ecart_remb
FROM
(
SELECT calc_valo, ghs, MAX(rss_id) AS rss_id, count(*) AS nb
FROM w_valosej
WHERE (gen_mnt_ant2 <> 0 OR gen_mnt_ant_am <> 0)
GROUP BY 1,2
) subview1
JOIN
(
SELECT calc_valo,
CASE WHEN round((SUM(calc_mnt_ant1) - SUM(w_valosej.gen_mnt_ant1))*100,0) >= 0 THEN 0.01 ELSE -0.01 END AS ecart_br1,
CASE WHEN round((SUM(calc_mnt_ant2) - SUM(w_valosej.gen_mnt_ant2))*100,0) >= 0 THEN 0.01 ELSE -0.01 END AS ecart_br2,
CASE WHEN round((SUM(calc_mnt_ant_am) - SUM(w_valosej.gen_mnt_ant_am))*100,0) >= 0 THEN 0.01 ELSE -0.01 END AS ecart_remb,
abs(round((SUM(calc_mnt_ant1) - SUM(w_valosej.gen_mnt_ant1))*100,0)) AS nb_ecart_br1,
abs(round((SUM(calc_mnt_ant2) - SUM(w_valosej.gen_mnt_ant2))*100,0)) AS nb_ecart_br2,
abs(round((SUM(calc_mnt_ant_am) - SUM(w_valosej.gen_mnt_ant_am))*100,0)) AS nb_ecart_remb
FROM w_valosej
WHERE (gen_mnt_ant2 <> 0 OR gen_mnt_ant_am <> 0)
GROUP BY 1
) subview2 ON subview1.calc_valo = subview2.calc_valo
ORDER BY rss_id
) subview
WHERE w_valosej.rss_id = subview.rss_id AND
(
ecart_br2 <> 0 OR
ecart_remb <> 0
)
;
-- Ventilation arrondi NN1 par ghs avec 1 centime par dossier
UPDATE w_valosej SET
gen_mnt_nn11 = round(calc_mnt_nn11 + ecart_br1,2),
gen_mnt_nn12 = round(calc_mnt_nn12 + ecart_br2,2),
gen_mnt_nn1_am = round(calc_mnt_nn1_am + ecart_remb,2)
FROM
(
SELECT w_valosej.rss_id,
row_number() OVER (PARTITION BY w_valosej.ghs, w_valosej.coefrep, w_valosej.coeftrans, w_valosej.calc_valo ORDER BY rss_id),
CASE WHEN row_number() OVER (PARTITION BY w_valosej.ghs, w_valosej.coefrep, w_valosej.coeftrans, w_valosej.calc_valo ORDER BY rss_id) <= nb_ecart_br1 THEN ecart_br1 ELSE 0 END AS ecart_br1,
CASE WHEN row_number() OVER (PARTITION BY w_valosej.ghs, w_valosej.coefrep, w_valosej.coeftrans, w_valosej.calc_valo ORDER BY rss_id) <= nb_ecart_br2 THEN ecart_br2 ELSE 0 END AS ecart_br2,
CASE WHEN row_number() OVER (PARTITION BY w_valosej.ghs, w_valosej.coefrep, w_valosej.coeftrans, w_valosej.calc_valo ORDER BY rss_id) <= nb_ecart_remb THEN ecart_remb ELSE 0 END AS ecart_remb
FROM w_valosej
JOIN
(
SELECT ghs, coefrep, coeftrans, calc_valo,
CASE WHEN round((SUM(calc_mnt_nn11) - SUM(round(w_valosej.calc_mnt_nn11,2)))*100,0) >= 0 THEN 0.01 ELSE -0.01 END AS ecart_br1,
CASE WHEN round((SUM(calc_mnt_nn12) - SUM(round(w_valosej.calc_mnt_nn12,2)))*100,0) >= 0 THEN 0.01 ELSE -0.01 END AS ecart_br2,
CASE WHEN round((SUM(calc_mnt_nn1_am) - SUM(round(w_valosej.calc_mnt_nn1_am,2)))*100,0) >= 0 THEN 0.01 ELSE -0.01 END AS ecart_remb,
abs(round((SUM(calc_mnt_nn11) - SUM(round(w_valosej.calc_mnt_nn11,2)))*100,0)) AS nb_ecart_br1,
abs(round((SUM(calc_mnt_nn12) - SUM(round(w_valosej.calc_mnt_nn12,2)))*100,0)) AS nb_ecart_br2,
abs(round((SUM(calc_mnt_nn1_am) - SUM(round(w_valosej.calc_mnt_nn1_am,2)))*100,0)) AS nb_ecart_remb
FROM w_valosej
WHERE (calc_mnt_nn12 <> 0 OR calc_mnt_nn1_am <> 0)
GROUP BY 1,2,3,4
) subview ON
w_valosej.ghs = subview.ghs AND
w_valosej.coefrep = subview.coefrep AND
w_valosej.coeftrans = subview.coeftrans AND
w_valosej.calc_valo = subview.calc_valo AND
(calc_mnt_nn12 <> 0 OR calc_mnt_nn1_am <> 0)
ORDER BY rss_id
) subview
WHERE w_valosej.rss_id = subview.rss_id
;
-- Ventilation arrondi NN1 sur total avec 1 centime ghs
UPDATE w_valosej SET
gen_mnt_nn11 = gen_mnt_nn11 + ecart_br1,
gen_mnt_nn12 = gen_mnt_nn12 + ecart_br2,
gen_mnt_nn1_am = gen_mnt_nn1_am + ecart_remb
FROM
(
SELECT subview1.rss_id, row_number() OVER (PARTITION BY subview1.calc_valo ORDER BY subview1.nb DESC),
CASE WHEN row_number() OVER (PARTITION BY subview1.calc_valo ORDER BY subview1.nb DESC) <= nb_ecart_br1 THEN ecart_br1 ELSE 0 END AS ecart_br1,
CASE WHEN row_number() OVER (PARTITION BY subview1.calc_valo ORDER BY subview1.nb DESC) <= nb_ecart_br2 THEN ecart_br2 ELSE 0 END AS ecart_br2,
CASE WHEN row_number() OVER (PARTITION BY subview1.calc_valo ORDER BY subview1.nb DESC) <= nb_ecart_remb THEN ecart_remb ELSE 0 END AS ecart_remb
FROM
(
SELECT calc_valo, ghs, MAX(rss_id) AS rss_id, count(*) AS nb
FROM w_valosej
WHERE (gen_mnt_nn12 <> 0 OR gen_mnt_nn1_am <> 0)
GROUP BY 1,2
) subview1
JOIN
(
SELECT calc_valo,
CASE WHEN round((SUM(calc_mnt_nn11) - SUM(w_valosej.gen_mnt_nn11))*100,0) >= 0 THEN 0.01 ELSE -0.01 END AS ecart_br1,
CASE WHEN round((SUM(calc_mnt_nn12) - SUM(w_valosej.gen_mnt_nn12))*100,0) >= 0 THEN 0.01 ELSE -0.01 END AS ecart_br2,
CASE WHEN round((SUM(calc_mnt_nn1_am) - SUM(w_valosej.gen_mnt_nn1_am))*100,0) >= 0 THEN 0.01 ELSE -0.01 END AS ecart_remb,
abs(round((SUM(calc_mnt_nn11) - SUM(w_valosej.gen_mnt_nn11))*100,0)) AS nb_ecart_br1,
abs(round((SUM(calc_mnt_nn12) - SUM(w_valosej.gen_mnt_nn12))*100,0)) AS nb_ecart_br2,
abs(round((SUM(calc_mnt_nn1_am) - SUM(w_valosej.gen_mnt_nn1_am))*100,0)) AS nb_ecart_remb
FROM w_valosej
WHERE (gen_mnt_nn12 <> 0 OR gen_mnt_nn1_am <> 0)
GROUP BY 1
) subview2 ON subview1.calc_valo = subview2.calc_valo
ORDER BY rss_id
) subview
WHERE w_valosej.rss_id = subview.rss_id AND
(
ecart_br2 <> 0 OR
ecart_remb <> 0
)
;
-- Ventilation arrondi SC par ghs avec 1 centime par dossier
UPDATE w_valosej SET
gen_mnt_sc1 = round(calc_mnt_sc1 + ecart_br1,2),
gen_mnt_sc2 = round(calc_mnt_sc2 + ecart_br2,2),
gen_mnt_sc_am = round(calc_mnt_sc_am + ecart_remb,2)
FROM
(
SELECT w_valosej.rss_id,
row_number() OVER (PARTITION BY w_valosej.ghs, w_valosej.coefrep, w_valosej.coeftrans, w_valosej.calc_valo ORDER BY rss_id),
CASE WHEN row_number() OVER (PARTITION BY w_valosej.ghs, w_valosej.coefrep, w_valosej.coeftrans, w_valosej.calc_valo ORDER BY rss_id) <= nb_ecart_br1 THEN ecart_br1 ELSE 0 END AS ecart_br1,
CASE WHEN row_number() OVER (PARTITION BY w_valosej.ghs, w_valosej.coefrep, w_valosej.coeftrans, w_valosej.calc_valo ORDER BY rss_id) <= nb_ecart_br2 THEN ecart_br2 ELSE 0 END AS ecart_br2,
CASE WHEN row_number() OVER (PARTITION BY w_valosej.ghs, w_valosej.coefrep, w_valosej.coeftrans, w_valosej.calc_valo ORDER BY rss_id) <= nb_ecart_remb THEN ecart_remb ELSE 0 END AS ecart_remb
FROM w_valosej
JOIN
(
SELECT ghs, coefrep, coeftrans, calc_valo,
CASE WHEN round((SUM(calc_mnt_sc1) - SUM(round(w_valosej.calc_mnt_sc1,2)))*100,0) >= 0 THEN 0.01 ELSE -0.01 END AS ecart_br1,
CASE WHEN round((SUM(calc_mnt_sc2) - SUM(round(w_valosej.calc_mnt_sc2,2)))*100,0) >= 0 THEN 0.01 ELSE -0.01 END AS ecart_br2,
CASE WHEN round((SUM(calc_mnt_sc_am) - SUM(round(w_valosej.calc_mnt_sc_am,2)))*100,0) >= 0 THEN 0.01 ELSE -0.01 END AS ecart_remb,
abs(round((SUM(calc_mnt_sc1) - SUM(round(w_valosej.calc_mnt_sc1,2)))*100,0)) AS nb_ecart_br1,
abs(round((SUM(calc_mnt_sc2) - SUM(round(w_valosej.calc_mnt_sc2,2)))*100,0)) AS nb_ecart_br2,
abs(round((SUM(calc_mnt_sc_am) - SUM(round(w_valosej.calc_mnt_sc_am,2)))*100,0)) AS nb_ecart_remb
FROM w_valosej
WHERE (calc_mnt_sc2 <> 0 OR calc_mnt_sc_am <> 0)
GROUP BY 1,2,3,4
) subview ON
w_valosej.ghs = subview.ghs AND
w_valosej.coefrep = subview.coefrep AND
w_valosej.coeftrans = subview.coeftrans AND
w_valosej.calc_valo = subview.calc_valo AND
(calc_mnt_sc2 <> 0 OR calc_mnt_sc_am <> 0)
ORDER BY rss_id
) subview
WHERE w_valosej.rss_id = subview.rss_id
;
-- Ventilation arrondi SC sur total avec 1 centime ghs
UPDATE w_valosej SET
gen_mnt_sc1 = gen_mnt_sc1 + ecart_br1,
gen_mnt_sc2 = gen_mnt_sc2 + ecart_br2,
gen_mnt_sc_am = gen_mnt_sc_am + ecart_remb
FROM
(
SELECT subview1.rss_id, row_number() OVER (PARTITION BY subview1.calc_valo ORDER BY subview1.nb DESC),
CASE WHEN row_number() OVER (PARTITION BY subview1.calc_valo ORDER BY subview1.nb DESC) <= nb_ecart_br1 THEN ecart_br1 ELSE 0 END AS ecart_br1,
CASE WHEN row_number() OVER (PARTITION BY subview1.calc_valo ORDER BY subview1.nb DESC) <= nb_ecart_br2 THEN ecart_br2 ELSE 0 END AS ecart_br2,
CASE WHEN row_number() OVER (PARTITION BY subview1.calc_valo ORDER BY subview1.nb DESC) <= nb_ecart_remb THEN ecart_remb ELSE 0 END AS ecart_remb
FROM
(
SELECT calc_valo, ghs, MAX(rss_id) AS rss_id, count(*) AS nb
FROM w_valosej
WHERE (gen_mnt_sc2 <> 0 OR gen_mnt_sc_am <> 0)
GROUP BY 1,2
) subview1
JOIN
(
SELECT calc_valo,
CASE WHEN round((SUM(calc_mnt_sc1) - SUM(w_valosej.gen_mnt_sc1))*100,0) >= 0 THEN 0.01 ELSE -0.01 END AS ecart_br1,
CASE WHEN round((SUM(calc_mnt_sc2) - SUM(w_valosej.gen_mnt_sc2))*100,0) >= 0 THEN 0.01 ELSE -0.01 END AS ecart_br2,
CASE WHEN round((SUM(calc_mnt_sc_am) - SUM(w_valosej.gen_mnt_sc_am))*100,0) >= 0 THEN 0.01 ELSE -0.01 END AS ecart_remb,
abs(round((SUM(calc_mnt_sc1) - SUM(w_valosej.gen_mnt_sc1))*100,0)) AS nb_ecart_br1,
abs(round((SUM(calc_mnt_sc2) - SUM(w_valosej.gen_mnt_sc2))*100,0)) AS nb_ecart_br2,
abs(round((SUM(calc_mnt_sc_am) - SUM(w_valosej.gen_mnt_sc_am))*100,0)) AS nb_ecart_remb
FROM w_valosej
WHERE (gen_mnt_sc2 <> 0 OR gen_mnt_sc_am <> 0)
GROUP BY 1
) subview2 ON subview1.calc_valo = subview2.calc_valo
ORDER BY rss_id
) subview
WHERE w_valosej.rss_id = subview.rss_id AND
(
ecart_br2 <> 0 OR
ecart_remb <> 0
)
;
-- Ventilation arrondi STF par ghs avec 1 centime par dossier
UPDATE w_valosej SET
gen_mnt_si1 = round(calc_mnt_si1 + ecart_br1,2),
gen_mnt_si2 = round(calc_mnt_si2 + ecart_br2,2),
gen_mnt_si_am = round(calc_mnt_si_am + ecart_remb,2)
FROM
(
SELECT w_valosej.rss_id,
row_number() OVER (PARTITION BY w_valosej.ghs, w_valosej.coefrep, w_valosej.coeftrans, w_valosej.calc_valo ORDER BY rss_id),
CASE WHEN row_number() OVER (PARTITION BY w_valosej.ghs, w_valosej.coefrep, w_valosej.coeftrans, w_valosej.calc_valo ORDER BY rss_id) <= nb_ecart_br1 THEN ecart_br1 ELSE 0 END AS ecart_br1,
CASE WHEN row_number() OVER (PARTITION BY w_valosej.ghs, w_valosej.coefrep, w_valosej.coeftrans, w_valosej.calc_valo ORDER BY rss_id) <= nb_ecart_br2 THEN ecart_br2 ELSE 0 END AS ecart_br2,
CASE WHEN row_number() OVER (PARTITION BY w_valosej.ghs, w_valosej.coefrep, w_valosej.coeftrans, w_valosej.calc_valo ORDER BY rss_id) <= nb_ecart_remb THEN ecart_remb ELSE 0 END AS ecart_remb
FROM w_valosej
JOIN
(
SELECT ghs, coefrep, coeftrans,calc_valo,
CASE WHEN round((SUM(calc_mnt_si1) - SUM(round(w_valosej.calc_mnt_si1,2)))*100,0) >= 0 THEN 0.01 ELSE -0.01 END AS ecart_br1,
CASE WHEN round((SUM(calc_mnt_si2) - SUM(round(w_valosej.calc_mnt_si2,2)))*100,0) >= 0 THEN 0.01 ELSE -0.01 END AS ecart_br2,
CASE WHEN round((SUM(calc_mnt_si_am) - SUM(round(w_valosej.calc_mnt_si_am,2)))*100,0) >= 0 THEN 0.01 ELSE -0.01 END AS ecart_remb,
abs(round((SUM(calc_mnt_si1) - SUM(round(w_valosej.calc_mnt_si1,2)))*100,0)) AS nb_ecart_br1,
abs(round((SUM(calc_mnt_si2) - SUM(round(w_valosej.calc_mnt_si2,2)))*100,0)) AS nb_ecart_br2,
abs(round((SUM(calc_mnt_si_am) - SUM(round(w_valosej.calc_mnt_si_am,2)))*100,0)) AS nb_ecart_remb
FROM w_valosej
WHERE (calc_mnt_si2 <> 0 OR calc_mnt_si_am <> 0)
GROUP BY 1,2,3,4
) subview ON
w_valosej.ghs = subview.ghs AND
w_valosej.coefrep = subview.coefrep AND
w_valosej.coeftrans = subview.coeftrans AND
w_valosej.calc_valo = subview.calc_valo AND
(calc_mnt_si2 <> 0 OR calc_mnt_si_am <> 0)
ORDER BY rss_id
) subview
WHERE w_valosej.rss_id = subview.rss_id
;
-- Ventilation arrondi STF sur total avec 1 centime ghs
UPDATE w_valosej SET
gen_mnt_si1 = gen_mnt_si1 + ecart_br1,
gen_mnt_si2 = gen_mnt_si2 + ecart_br2,
gen_mnt_si_am = gen_mnt_si_am + ecart_remb
FROM
(
SELECT subview1.rss_id, row_number() OVER (PARTITION BY subview1.calc_valo ORDER BY subview1.nb DESC),
CASE WHEN row_number() OVER (PARTITION BY subview1.calc_valo ORDER BY subview1.nb DESC) <= nb_ecart_br1 THEN ecart_br1 ELSE 0 END AS ecart_br1,
CASE WHEN row_number() OVER (PARTITION BY subview1.calc_valo ORDER BY subview1.nb DESC) <= nb_ecart_br2 THEN ecart_br2 ELSE 0 END AS ecart_br2,
CASE WHEN row_number() OVER (PARTITION BY subview1.calc_valo ORDER BY subview1.nb DESC) <= nb_ecart_remb THEN ecart_remb ELSE 0 END AS ecart_remb
FROM
(
SELECT calc_valo, ghs, MAX(rss_id) AS rss_id, count(*) AS nb
FROM w_valosej
WHERE (gen_mnt_si2 <> 0 OR gen_mnt_si_am <> 0)
GROUP BY 1,2
) subview1
JOIN
(
SELECT calc_valo,
CASE WHEN round((SUM(calc_mnt_si1) - SUM(w_valosej.gen_mnt_si1))*100,0) >= 0 THEN 0.01 ELSE -0.01 END AS ecart_br1,
CASE WHEN round((SUM(calc_mnt_si2) - SUM(w_valosej.gen_mnt_si2))*100,0) >= 0 THEN 0.01 ELSE -0.01 END AS ecart_br2,
CASE WHEN round((SUM(calc_mnt_si_am) - SUM(w_valosej.gen_mnt_si_am))*100,0) >= 0 THEN 0.01 ELSE -0.01 END AS ecart_remb,
abs(round((SUM(calc_mnt_si1) - SUM(w_valosej.gen_mnt_si1))*100,0)) AS nb_ecart_br1,
abs(round((SUM(calc_mnt_si2) - SUM(w_valosej.gen_mnt_si2))*100,0)) AS nb_ecart_br2,
abs(round((SUM(calc_mnt_si_am) - SUM(w_valosej.gen_mnt_si_am))*100,0)) AS nb_ecart_remb
FROM w_valosej
WHERE (gen_mnt_si2 <> 0 OR gen_mnt_si_am <> 0)
GROUP BY 1
) subview2 ON subview1.calc_valo = subview2.calc_valo
ORDER BY rss_id
) subview
WHERE w_valosej.rss_id = subview.rss_id AND
(
ecart_br2 <> 0 OR
ecart_remb <> 0
)
;
-- Ventilation arrondi REA par ghs avec 1 centime par dossier
UPDATE w_valosej SET
gen_mnt_rea1 = round(calc_mnt_rea1 + ecart_br1,2),
gen_mnt_rea2 = round(calc_mnt_rea2 + ecart_br2,2),
gen_mnt_rea_am = round(calc_mnt_rea_am + ecart_remb,2)
FROM
(
SELECT w_valosej.rss_id,
row_number() OVER (PARTITION BY w_valosej.ghs, w_valosej.coefrep, w_valosej.coeftrans, w_valosej.calc_valo ORDER BY rss_id),
CASE WHEN row_number() OVER (PARTITION BY w_valosej.ghs, w_valosej.coefrep, w_valosej.coeftrans, w_valosej.calc_valo ORDER BY rss_id) <= nb_ecart_br1 THEN ecart_br1 ELSE 0 END AS ecart_br1,
CASE WHEN row_number() OVER (PARTITION BY w_valosej.ghs, w_valosej.coefrep, w_valosej.coeftrans, w_valosej.calc_valo ORDER BY rss_id) <= nb_ecart_br2 THEN ecart_br2 ELSE 0 END AS ecart_br2,
CASE WHEN row_number() OVER (PARTITION BY w_valosej.ghs, w_valosej.coefrep, w_valosej.coeftrans, w_valosej.calc_valo ORDER BY rss_id) <= nb_ecart_remb THEN ecart_remb ELSE 0 END AS ecart_remb
FROM w_valosej
JOIN
(
SELECT ghs, coefrep, coeftrans, calc_valo,
CASE WHEN round((SUM(calc_mnt_rea1) - SUM(round(w_valosej.calc_mnt_rea1,2)))*100,0) >= 0 THEN 0.01 ELSE -0.01 END AS ecart_br1,
CASE WHEN round((SUM(calc_mnt_rea2) - SUM(round(w_valosej.calc_mnt_rea2,2)))*100,0) >= 0 THEN 0.01 ELSE -0.01 END AS ecart_br2,
CASE WHEN round((SUM(calc_mnt_rea_am) - SUM(round(w_valosej.calc_mnt_rea_am,2)))*100,0) >= 0 THEN 0.01 ELSE -0.01 END AS ecart_remb,
abs(round((SUM(calc_mnt_rea1) - SUM(round(w_valosej.calc_mnt_rea1,2)))*100,0)) AS nb_ecart_br1,
abs(round((SUM(calc_mnt_rea2) - SUM(round(w_valosej.calc_mnt_rea2,2)))*100,0)) AS nb_ecart_br2,
abs(round((SUM(calc_mnt_rea_am) - SUM(round(w_valosej.calc_mnt_rea_am,2)))*100,0)) AS nb_ecart_remb
FROM w_valosej
WHERE (calc_mnt_rea2 <> 0 OR calc_mnt_rea_am <> 0)
GROUP BY 1,2,3,4
) subview ON
w_valosej.ghs = subview.ghs AND
w_valosej.coefrep = subview.coefrep AND
w_valosej.coeftrans = subview.coeftrans AND
w_valosej.calc_valo = subview.calc_valo AND
(calc_mnt_rea2 <> 0 OR calc_mnt_rea_am <> 0)
ORDER BY rss_id
) subview
WHERE w_valosej.rss_id = subview.rss_id
;
-- Ventilation arrondi REA sur total avec 1 centime ghs
UPDATE w_valosej SET
gen_mnt_rea1 = gen_mnt_rea1 + ecart_br1,
gen_mnt_rea2 = gen_mnt_rea2 + ecart_br2,
gen_mnt_rea_am = gen_mnt_rea_am + ecart_remb
FROM
(
SELECT subview1.rss_id, row_number() OVER (PARTITION BY subview1.calc_valo ORDER BY subview1.nb DESC),
CASE WHEN row_number() OVER (PARTITION BY subview1.calc_valo ORDER BY subview1.nb DESC) <= nb_ecart_br1 THEN ecart_br1 ELSE 0 END AS ecart_br1,
CASE WHEN row_number() OVER (PARTITION BY subview1.calc_valo ORDER BY subview1.nb DESC) <= nb_ecart_br2 THEN ecart_br2 ELSE 0 END AS ecart_br2,
CASE WHEN row_number() OVER (PARTITION BY subview1.calc_valo ORDER BY subview1.nb DESC) <= nb_ecart_remb THEN ecart_remb ELSE 0 END AS ecart_remb
FROM
(
SELECT calc_valo, ghs, MAX(rss_id) AS rss_id, count(*) AS nb
FROM w_valosej
WHERE (gen_mnt_rea2 <> 0 OR gen_mnt_rea_am <> 0)
GROUP BY 1,2
) subview1
JOIN
(
SELECT calc_valo,
CASE WHEN round((SUM(calc_mnt_rea1) - SUM(w_valosej.gen_mnt_rea1))*100,0) >= 0 THEN 0.01 ELSE -0.01 END AS ecart_br1,
CASE WHEN round((SUM(calc_mnt_rea2) - SUM(w_valosej.gen_mnt_rea2))*100,0) >= 0 THEN 0.01 ELSE -0.01 END AS ecart_br2,
CASE WHEN round((SUM(calc_mnt_rea_am) - SUM(w_valosej.gen_mnt_rea_am))*100,0) >= 0 THEN 0.01 ELSE -0.01 END AS ecart_remb,
abs(round((SUM(calc_mnt_rea1) - SUM(w_valosej.gen_mnt_rea1))*100,0)) AS nb_ecart_br1,
abs(round((SUM(calc_mnt_rea2) - SUM(w_valosej.gen_mnt_rea2))*100,0)) AS nb_ecart_br2,
abs(round((SUM(calc_mnt_rea_am) - SUM(w_valosej.gen_mnt_rea_am))*100,0)) AS nb_ecart_remb
FROM w_valosej
WHERE (gen_mnt_rea2 <> 0 OR gen_mnt_rea_am <> 0)
GROUP BY 1
) subview2 ON subview1.calc_valo = subview2.calc_valo
ORDER BY rss_id
) subview
WHERE w_valosej.rss_id = subview.rss_id AND
(
ecart_br2 <> 0 OR
ecart_remb <> 0
)
;
RAISE NOTICE '% | IDENTIFICATION SEJOURS NON VALORISES', to_char(CURRENT_TIMESTAMP, 'YYYY-MM-DD HH24:MI:ss');
-- Correction du rehosp meme GHM
EXECUTE FORMAT ('
UPDATE %I.p_rss SET
rehosp_meme_ghm = CASE WHEN mnt_ghs50 <> 0 THEN ''1''::text ELSE ''0''::text END
FROM
w_valosej
WHERE 1=1
AND w_valosej.rss_id = p_rss.oid
AND p_rss.rehosp_meme_ghm IS DISTINCT FROM CASE WHEN mnt_ghs50 <> 0 THEN ''1''::text ELSE ''0''::text END
', i_schema);
-- Correction du traitement ePMSI si séjour non valorisé par Valosej mais valorisé par CTI (AMO ou IVG)
EXECUTE FORMAT ('
UPDATE %I.p_rss SET
traitement_epmsi = ''26''::text
FROM
w_valosej
WHERE 1=1
AND w_valosej.rss_id = p_rss.oid
AND p_rss.traitement_epmsi IN (''30'', ''32'')
AND w_valosej.valo = 0
', i_schema);
RAISE NOTICE '% | RESET MONTANT REMBOURSE SUR SEJOURS NON VALORISES', to_char(CURRENT_TIMESTAMP, 'YYYY-MM-DD HH24:MI:ss');
-- Coefficient mco
EXECUTE FORMAT ('
UPDATE %I.p_rsf_detail
SET
coefficient_mco = w_valosej.coefrep * w_valosej.coeftrans * w_valosej.coefp
FROM
w_valosej, pmsi.t_prestations
WHERE 1=1
AND p_rsf_detail.rss_id = w_valosej.rss_id
AND p_rsf_detail.prestation_id = t_prestations.oid
AND p_rsf_detail.est_ligne_rss IS DISTINCT FROM ''0''
AND t_prestations.code IN (''GHS'', ''EXH'', ''REA'', ''SRC'', ''STF'', ''ANT'', ''IRRE1'', ''IRRE4'', ''IRRE5'', ''IRRE6'', ''IRRE7'', ''IRRE9'', ''IRRE10'', ''IRRE11'', ''IRRE12'', ''AMD'', ''RAP'', ''OHB'', ''SDC'', ''AMD'', ''AMF'', ''APD'', ''IMD'', ''IPD'')
', i_schema);
EXECUTE FORMAT ('
UPDATE %I.p_rsf_detail
SET
coefficient_mco = w_valosej.coefrep * w_valosej.coeftrans * w_valosej.coefp
FROM
w_valosej, pmsi.t_prestations
WHERE 1=1
AND p_rsf_detail.rss_id = w_valosej.rss_id
AND p_rsf_detail.prestation_id = t_prestations.oid
AND p_rsf_detail.est_ligne_rss IS DISTINCT FROM ''0''
AND t_prestations.code IN (''D09'', ''D19'', ''DIP'')
', i_schema);
-- Montant remboursé à 0 si non valorisé sur VALOSEJ
EXECUTE FORMAT ('
UPDATE %I.p_rsf_detail
SET
sejour_remboursable = 0,
update_rules = array_append(p_rsf_detail.update_rules, 102)
FROM
w_valosej
JOIN w_valocti ON w_valocti.rss_id = w_valosej.rss_id
AND w_valocti.prestation_code IN (''GHS'', ''EXH'', ''SRC'', ''STF'', ''ANT'', ''IRRE1'', ''IRRE4'', ''IRRE5'', ''IRRE6'', ''IRRE7'', ''IRRE9'', ''IRRE10'', ''IRRE11'', ''IRRE12'', ''AMD'', ''RAP'', ''OHB'', ''SDC'', ''AMD'', ''AMF'', ''APD'', ''IMD'', ''IPD'')
WHERE 1=1
AND p_rsf_detail.rss_id = w_valosej.rss_id
--AND p_rsf_detail.rss_id = w_valocti.rss_id
AND p_rsf_detail.prestation_id = w_valocti.prestation_id
AND p_rsf_detail.est_ligne_rss IS DISTINCT FROM ''0''
AND w_valosej.valo = 0
AND p_rsf_detail.sejour_remboursable != 0
', i_schema);
-- Suppression des IVG non valorisé
EXECUTE FORMAT ('
DELETE FROM %I.p_rsf_detail
USING
w_valosej
,w_valocti
WHERE 1=1
AND w_valocti.rss_id = w_valosej.rss_id
AND p_rsf_detail.rss_id = w_valosej.rss_id
AND p_rsf_detail.prestation_id = w_valocti.prestation_id
AND w_valocti.prestation_code IN (''AMD'', ''AMF'', ''APD'', ''IMD'')
AND w_valosej.valo = 0
', i_schema);
RAISE NOTICE '% | TRAITEMENT GHS', to_char(CURRENT_TIMESTAMP, 'YYYY-MM-DD HH24:MI:ss');
-- GHS
EXECUTE FORMAT ('
UPDATE %I.p_rsf_detail SET
base_remboursement = w_valosej.gen_mnt_ghs1 + w_valosej.gen_mnt_exinf1 + w_valosej.gen_mnt_ghs501,
sejour_remboursable = CASE WHEN w_valosej.valo IN (1,3,4,5) THEN w_valosej.gen_mnt_ghs_am + w_valosej.gen_mnt_exinf_am + w_valosej.gen_mnt_ghs50_am ELSE 0 END,
base_remboursement_sauf_transition = CASE WHEN %s >= 2018 THEN w_valosej.gen_mnt_ghs2 + w_valosej.gen_mnt_exinf2 + w_valosej.gen_mnt_ghs502 ELSE base_remboursement_sauf_transition END,
coefficient = CASE WHEN %s >= 2018 THEN round(base.cti_division(w_valosej.gen_mnt_ghs2 + w_valosej.gen_mnt_exinf2 + w_valosej.gen_mnt_ghs502, w_valosej.gen_mnt_ghs2), 7) ELSE coefficient END,
update_rules = array_append(p_rsf_detail.update_rules, 103)
FROM
w_valosej
JOIN w_valocti ON w_valocti.rss_id = w_valosej.rss_id AND w_valocti.prestation_code = ''GHS''
WHERE 1=1
AND p_rsf_detail.rss_id = w_valocti.rss_id
AND p_rsf_detail.prestation_id = w_valocti.prestation_id
AND p_rsf_detail.est_ligne_rss IS DISTINCT FROM ''0''
AND w_valocti.nb = 1
', i_schema, v_annee, v_annee);
RAISE NOTICE '% | TRAITEMENT EXH', to_char(CURRENT_TIMESTAMP, 'YYYY-MM-DD HH24:MI:ss');
-- EXH
DROP TABLE IF EXISTS w_multi_exh;
EXECUTE FORMAT ('
CREATE TEMP TABLE w_multi_exh AS
SELECT
p_rsf_detail.rss_id,
t_prestations.oid as prestation_id,
p_rss.mode_sortie
FROM
%I.p_rsf_detail
JOIN %I.p_rss ON p_rss.oid = p_rsf_detail.rss_id
JOIN pmsi.t_prestations ON p_rsf_detail.prestation_id = t_prestations.oid AND t_prestations.code = ''EXH''
WHERE 1=1
AND import_id = %s
AND p_rsf_detail.est_ligne_rss IS DISTINCT FROM ''0''
GROUP BY p_rsf_detail.rss_id, t_prestations.oid, p_rss.mode_sortie
HAVING count(*) > 1
', i_schema, i_schema, i_import_id);
-- Sejours avec un seul EXH
EXECUTE FORMAT ('
UPDATE %I.p_rsf_detail SET
base_remboursement = w_valosej.gen_mnt_exh1,
sejour_remboursable = CASE WHEN w_valosej.valo IN (1,3,4,5) THEN w_valosej.gen_mnt_exh_am ELSE 0 END,
base_remboursement_sauf_transition = CASE WHEN %s >= 2018 THEN w_valosej.gen_mnt_exh2 ELSE base_remboursement_sauf_transition END,
update_rules = array_append(p_rsf_detail.update_rules, 104)
FROM
w_valosej
JOIN w_valocti ON w_valocti.rss_id = w_valosej.rss_id AND w_valocti.prestation_code = ''EXH''
LEFT JOIN w_multi_exh ON w_multi_exh.rss_id = w_valosej.rss_id
WHERE 1=1
AND p_rsf_detail.rss_id = w_valocti.rss_id
AND p_rsf_detail.prestation_id = w_valocti.prestation_id
AND p_rsf_detail.est_ligne_rss IS DISTINCT FROM ''0''
AND w_multi_exh.rss_id IS NULL
', i_schema, v_annee);
-- EXH à 100% au delà du 30ème jour d'hospit si tx_remb du séjour à 80%
EXECUTE FORMAT ('
WITH w_valosej_exh AS (
SELECT
w_valosej.rss_id,
w_multi_exh.prestation_id,
w_valosej.nbexh,
w_valosej.mnt_exh_am,
EXTRACT(DAY FROM w_valosej.date_sor - w_valosej.date_ent) - 30 + CASE WHEN w_multi_exh.mode_sortie = ''9'' THEN 1 ELSE 0 END as nbexh_100,
round((w_valosej.gen_mnt_exh_am * (EXTRACT(DAY FROM w_valosej.date_sor - w_valosej.date_ent) - 30 + CASE WHEN w_multi_exh.mode_sortie = ''9'' THEN 1 ELSE 0 END) / w_valosej.nbexh)::numeric, 2) as mnt_exh_am_100,
round((w_valosej.gen_mnt_exh1 * (EXTRACT(DAY FROM w_valosej.date_sor - w_valosej.date_ent) - 30 + CASE WHEN w_multi_exh.mode_sortie = ''9'' THEN 1 ELSE 0 END) / w_valosej.nbexh)::numeric, 2) as mnt_exh1_100,
round((w_valosej.gen_mnt_exh2 * (EXTRACT(DAY FROM w_valosej.date_sor - w_valosej.date_ent) - 30 + CASE WHEN w_multi_exh.mode_sortie = ''9'' THEN 1 ELSE 0 END) / w_valosej.nbexh)::numeric, 2) as mnt_exh2_100,
w_valosej.nbexh - (EXTRACT(DAY FROM w_valosej.date_sor - w_valosej.date_ent) - 30 - CASE WHEN w_multi_exh.mode_sortie = ''9'' THEN 1 ELSE 0 END) as nbexh_80,
round((w_valosej.gen_mnt_exh_am * (w_valosej.nbexh - (EXTRACT(DAY FROM w_valosej.date_sor - w_valosej.date_ent) - 30 + CASE WHEN w_multi_exh.mode_sortie = ''9'' THEN 1 ELSE 0 END)) / w_valosej.nbexh)::numeric, 2) as mnt_exh_am_80,
round((w_valosej.gen_mnt_exh1 * (w_valosej.nbexh - (EXTRACT(DAY FROM w_valosej.date_sor - w_valosej.date_ent) - 30 + CASE WHEN w_multi_exh.mode_sortie = ''9'' THEN 1 ELSE 0 END)) / w_valosej.nbexh)::numeric, 2) as mnt_exh1_80,
round((w_valosej.gen_mnt_exh2 * (w_valosej.nbexh - (EXTRACT(DAY FROM w_valosej.date_sor - w_valosej.date_ent) - 30 + CASE WHEN w_multi_exh.mode_sortie = ''9'' THEN 1 ELSE 0 END)) / w_valosej.nbexh)::numeric, 2) as mnt_exh2_80
FROM
w_valosej
JOIN w_multi_exh ON w_multi_exh.rss_id = w_valosej.rss_id
WHERE 1=1
AND extract(day from w_valosej.date_sor - w_valosej.date_ent) > 30
AND w_valosej.nbexh > 0
AND w_valosej.taux2 != 100
)
UPDATE %I.p_rsf_detail SET
base_remboursement = CASE
WHEN %s >= 2018 AND p_rsf_detail.nombre = w_valosej_exh.nbexh_80 THEN w_valosej_exh.mnt_exh1_80
WHEN %s >= 2018 AND p_rsf_detail.nombre = w_valosej_exh.nbexh_100 THEN w_valosej_exh.mnt_exh1_100
ELSE base_remboursement_sauf_transition
END,
sejour_remboursable = CASE
WHEN p_rsf_detail.nombre = w_valosej_exh.nbexh_80 THEN w_valosej_exh.mnt_exh_am_80
WHEN p_rsf_detail.nombre = w_valosej_exh.nbexh_100 THEN w_valosej_exh.mnt_exh_am_100
ELSE sejour_remboursable
END,
base_remboursement_sauf_transition = CASE
WHEN %s >= 2018 AND p_rsf_detail.nombre = w_valosej_exh.nbexh_80 THEN w_valosej_exh.mnt_exh2_80
WHEN %s >= 2018 AND p_rsf_detail.nombre = w_valosej_exh.nbexh_100 THEN w_valosej_exh.mnt_exh2_100
ELSE base_remboursement_sauf_transition
END,
update_rules = array_append(p_rsf_detail.update_rules, 105)
FROM
w_valosej_exh, pmsi.t_prestations
WHERE 1=1
AND p_rsf_detail.est_ligne_rss IS DISTINCT FROM ''0''
AND t_prestations.oid = p_rsf_detail.prestation_id
AND t_prestations.code = ''EXH''
AND w_valosej_exh.rss_id = p_rsf_detail.rss_id
AND w_valosej_exh.prestation_id = p_rsf_detail.prestation_id
', i_schema, v_annee, v_annee, v_annee, v_annee);
EXECUTE FORMAT ('
UPDATE %I.p_rsf_detail SET
base_remboursement = base_remboursement + ecart_exh1,
base_remboursement_sauf_transition = base_remboursement_sauf_transition + ecart_exh2,
sejour_remboursable = sejour_remboursable + ecart_exh_am
FROM
(
SELECT p_rsf_detail.no_rss, p_rsf_detail.rss_id,
(MAX(ARRAY[to_char(p_rsf_detail.base_remboursement,''FM000000000000000.00''),p_rsf_detail.CTID::text]))[2]::text AS CTID_adjust,
MAX(gen_mnt_exh1) - SUM(p_rsf_detail.base_remboursement) AS ecart_exh1,
MAX(gen_mnt_exh2) - SUM(p_rsf_detail.base_remboursement_sauf_transition) AS ecart_exh2,
MAX(gen_mnt_exh_am) - SUM(p_rsf_detail.sejour_remboursable) AS ecart_exh_am
FROM %I.p_rss p_rss
JOIN %I.p_rsf_detail p_rsf_detail ON p_rsf_detail.rss_id = p_rss.oid
JOIN pmsi.t_prestations ON prestation_id = t_prestations.oid
JOIN w_valosej on w_valosej.rss_id = p_rsf_detail.rss_id
WHERE t_prestations.code = ''EXH'' AND
valo <> 0
GROUP BY 1,2
HAVING abs(SUM(p_rsf_detail.base_remboursement) - MAX(gen_mnt_exh1)) <> 0 OR
abs(SUM(p_rsf_detail.base_remboursement_sauf_transition) - MAX(gen_mnt_exh2)) <> 0 OR
abs(SUM(p_rsf_detail.sejour_remboursable) - MAX(gen_mnt_exh_am)) <> 0
) subview
WHERE p_rsf_detail.rss_id = subview.rss_id AND
p_rsf_detail.CTID::text = subview.CTID_adjust
', i_schema, i_schema, i_schema);
RAISE NOTICE '% | TRAITEMENT SUPPLEMENTS', to_char(CURRENT_TIMESTAMP, 'YYYY-MM-DD HH24:MI:ss');
-- Suppléments
-- Sur VisualValoSej v1.7.8, il y a une erreur pour les suppléments IRRE7
-- la BR_HT est dans mnt_9622
-- mais le montant_remboursé est dans mnt_9623_am (et non mnt_9622_am)
EXECUTE FORMAT ('
UPDATE %I.p_rsf_detail
SET
sejour_remboursable = CASE
WHEN w_valosej.valo NOT IN (1,3,4,5) THEN 0
WHEN w_valocti.prestation_code = ''AMD'' THEN w_valosej.mnt_ivg_am
WHEN w_valocti.prestation_code = ''AMF'' THEN w_valosej.mnt_ivg_am
WHEN w_valocti.prestation_code = ''APD'' THEN w_valosej.mnt_ivg_am
WHEN w_valocti.prestation_code = ''IMD'' THEN w_valosej.mnt_ivg_am
WHEN w_valocti.prestation_code = ''IPD'' THEN w_valosej.mnt_ivg_am
WHEN w_valocti.prestation_code = ''ANT'' THEN w_valosej.mnt_ant_am
WHEN w_valocti.prestation_code = ''APHE'' THEN w_valosej.mnt_9615_am
WHEN w_valocti.prestation_code = ''DIP'' THEN w_valosej.mnt_dip_am
WHEN w_valocti.prestation_code = ''D09'' THEN w_valosej.mnt_supphd_am
WHEN w_valocti.prestation_code = ''D19'' THEN w_valosej.mnt_suppent2_am
WHEN w_valocti.prestation_code = ''IRRE1'' THEN w_valosej.mnt_9610_am
WHEN w_valocti.prestation_code = ''IRRE4'' THEN w_valosej.mnt_9619_am
WHEN w_valocti.prestation_code = ''IRRE5'' THEN w_valosej.mnt_9620_am
WHEN w_valocti.prestation_code = ''IRRE6'' THEN w_valosej.mnt_9621_am
WHEN w_valocti.prestation_code = ''IRRE7'' AND %s >= 2020 THEN w_valosej.mnt_9622_am
WHEN w_valocti.prestation_code = ''IRRE7'' AND %s < 2020 THEN w_valosej.mnt_9623_am
WHEN w_valocti.prestation_code = ''IRRE9'' THEN w_valosej.mnt_9625_am
WHEN w_valocti.prestation_code = ''IRRE10'' THEN w_valosej.mnt_9631_am
WHEN w_valocti.prestation_code = ''IRRE11'' THEN w_valosej.mnt_9632_am
WHEN w_valocti.prestation_code = ''IRRE12'' THEN w_valosej.mnt_9633_am
WHEN w_valocti.prestation_code = ''NN1'' THEN w_valosej.mnt_nn1_am
WHEN w_valocti.prestation_code = ''NN2'' THEN w_valosej.mnt_nn2_am
WHEN w_valocti.prestation_code = ''NN3'' THEN w_valosej.mnt_nn3_am
WHEN w_valocti.prestation_code = ''RAP'' THEN w_valosej.mnt_rap_am
WHEN w_valocti.prestation_code = ''REA'' THEN w_valosej.mnt_rea_am
WHEN w_valocti.prestation_code = ''SRC'' THEN w_valosej.mnt_sc_am
WHEN w_valocti.prestation_code = ''STF'' THEN w_valosej.mnt_si_am
WHEN w_valocti.prestation_code = ''OHB'' THEN w_valosej.mnt_caisson_am
WHEN w_valocti.prestation_code = ''SDC'' AND %s >= 2018 THEN w_valosej.mnt_sdc_am
ELSE p_rsf_detail.sejour_remboursable
END,
base_remboursement =
CASE
WHEN %s >= 2018 THEN
CASE w_valocti.prestation_code
WHEN ''AMD'' THEN w_valosej.mnt_ivg
WHEN ''AMF'' THEN w_valosej.mnt_ivg
WHEN ''APD'' THEN w_valosej.mnt_ivg
WHEN ''IMD'' THEN w_valosej.mnt_ivg
WHEN ''IPD'' THEN w_valosej.mnt_ivg
WHEN ''ANT'' THEN w_valosej.mnt_ant
WHEN ''APHE'' THEN w_valosej.mnt_9615
WHEN ''DIP'' THEN w_valosej.mnt_dip
WHEN ''D09'' THEN w_valosej.mnt_supphd
WHEN ''D19'' THEN w_valosej.mnt_suppent2_am
WHEN ''IRRE1'' THEN w_valosej.mnt_9610
WHEN ''IRRE4'' THEN w_valosej.mnt_9619
WHEN ''IRRE5'' THEN w_valosej.mnt_9620
WHEN ''IRRE6'' THEN w_valosej.mnt_9621
WHEN ''IRRE7'' THEN w_valosej.mnt_9622
WHEN ''IRRE9'' THEN w_valosej.mnt_9625
WHEN ''IRRE10'' THEN w_valosej.mnt_9631
WHEN ''IRRE11'' THEN w_valosej.mnt_9632
WHEN ''IRRE12'' THEN w_valosej.mnt_9633
WHEN ''NN1'' THEN w_valosej.mnt_nn1
WHEN ''NN2'' THEN w_valosej.mnt_nn2
WHEN ''NN3'' THEN w_valosej.mnt_nn3
WHEN ''RAP'' THEN w_valosej.mnt_rap
WHEN ''REA'' THEN w_valosej.mnt_rea
WHEN ''SRC'' THEN w_valosej.mnt_sc
WHEN ''STF'' THEN w_valosej.mnt_si
WHEN ''OHB'' THEN w_valosej.mnt_caisson
WHEN ''SDC'' THEN w_valosej.mnt_sdc
ELSE p_rsf_detail.base_remboursement
END * w_valosej.coefp
ELSE p_rsf_detail.base_remboursement
END,
base_remboursement_sauf_transition =
CASE
WHEN %s >= 2018 THEN
CASE w_valocti.prestation_code
WHEN ''AMD'' THEN w_valosej.mnt_ivg
WHEN ''AMF'' THEN w_valosej.mnt_ivg
WHEN ''APD'' THEN w_valosej.mnt_ivg
WHEN ''IMD'' THEN w_valosej.mnt_ivg
WHEN ''IPD'' THEN w_valosej.mnt_ivg
WHEN ''ANT'' THEN w_valosej.mnt_ant
WHEN ''APHE'' THEN w_valosej.mnt_9615
WHEN ''DIP'' THEN w_valosej.mnt_dip
WHEN ''D09'' THEN w_valosej.mnt_supphd
WHEN ''D19'' THEN w_valosej.mnt_suppent2_am
WHEN ''IRRE1'' THEN w_valosej.mnt_9610
WHEN ''IRRE4'' THEN w_valosej.mnt_9619
WHEN ''IRRE5'' THEN w_valosej.mnt_9620
WHEN ''IRRE6'' THEN w_valosej.mnt_9621
WHEN ''IRRE7'' THEN w_valosej.mnt_9622
WHEN ''IRRE9'' THEN w_valosej.mnt_9625
WHEN ''IRRE10'' THEN w_valosej.mnt_9631
WHEN ''IRRE11'' THEN w_valosej.mnt_9632
WHEN ''IRRE12'' THEN w_valosej.mnt_9633
WHEN ''NN1'' THEN w_valosej.mnt_nn1
WHEN ''NN2'' THEN w_valosej.mnt_nn2
WHEN ''NN3'' THEN w_valosej.mnt_nn3
WHEN ''RAP'' THEN w_valosej.mnt_rap
WHEN ''REA'' THEN w_valosej.mnt_rea
WHEN ''SRC'' THEN w_valosej.mnt_sc
WHEN ''STF'' THEN w_valosej.mnt_si
WHEN ''OHB'' THEN w_valosej.mnt_caisson
WHEN ''SDC'' THEN w_valosej.mnt_sdc
ELSE p_rsf_detail.base_remboursement_sauf_transition
END
ELSE base_remboursement_sauf_transition
END,
update_rules = array_append(p_rsf_detail.update_rules, 106)
FROM
w_valosej
JOIN w_valocti ON w_valocti.rss_id = w_valosej.rss_id
WHERE 1=1
AND p_rsf_detail.rss_id = w_valocti.rss_id
AND p_rsf_detail.prestation_id = w_valocti.prestation_id
AND p_rsf_detail.est_ligne_rss IS DISTINCT FROM ''0''
AND w_valocti.nb = 1
AND w_valocti.prestation_code IN (''AMD'', ''AMF'', ''APD'', ''APHE'', ''DIP'', ''D09'', ''D19'', ''IMD'', ''IPD'', ''IRRE1'', ''IRRE4'', ''IRRE5'', ''IRRE6'', ''IRRE7'', ''IRRE9'', ''IRRE10'', ''IRRE11'', ''IRRE12'', ''NN2'', ''NN3'', ''RAP'', ''OHB'', ''SDC'')
', i_schema, v_annee, v_annee, v_annee, v_annee, v_annee);
-- Suppléments
-- avec arrondis
EXECUTE FORMAT ('
UPDATE %I.p_rsf_detail
SET
base_remboursement =
CASE
WHEN %s >= 2018 THEN
CASE w_valocti.prestation_code
WHEN ''ANT'' THEN w_valosej.gen_mnt_ant1
WHEN ''NN1'' THEN w_valosej.gen_mnt_nn11
WHEN ''SRC'' THEN w_valosej.gen_mnt_sc1
WHEN ''STF'' THEN w_valosej.gen_mnt_si1
WHEN ''REA'' THEN w_valosej.gen_mnt_rea1
ELSE p_rsf_detail.base_remboursement
END
ELSE p_rsf_detail.base_remboursement
END,
sejour_remboursable = CASE
WHEN w_valosej.valo NOT IN (1,3,4,5) THEN 0
WHEN w_valocti.prestation_code = ''ANT'' THEN w_valosej.gen_mnt_ant_am
WHEN w_valocti.prestation_code = ''NN1'' THEN w_valosej.gen_mnt_nn1_am
WHEN w_valocti.prestation_code = ''SRC'' THEN w_valosej.gen_mnt_sc_am
WHEN w_valocti.prestation_code = ''STF'' THEN w_valosej.gen_mnt_si_am
WHEN w_valocti.prestation_code = ''REA'' THEN w_valosej.gen_mnt_rea_am
ELSE p_rsf_detail.sejour_remboursable
END,
base_remboursement_sauf_transition =
CASE
WHEN %s >= 2018 THEN
CASE w_valocti.prestation_code
WHEN ''ANT'' THEN w_valosej.gen_mnt_ant2
WHEN ''NN1'' THEN w_valosej.gen_mnt_nn12
WHEN ''SRC'' THEN w_valosej.gen_mnt_sc2
WHEN ''STF'' THEN w_valosej.gen_mnt_si2
WHEN ''REA'' THEN w_valosej.gen_mnt_rea2
ELSE p_rsf_detail.base_remboursement_sauf_transition
END
ELSE p_rsf_detail.base_remboursement_sauf_transition
END,
update_rules = array_append(p_rsf_detail.update_rules, 106)
FROM
w_valosej
JOIN w_valocti ON w_valocti.rss_id = w_valosej.rss_id
WHERE 1=1
AND p_rsf_detail.rss_id = w_valocti.rss_id
AND p_rsf_detail.prestation_id = w_valocti.prestation_id
AND p_rsf_detail.est_ligne_rss IS DISTINCT FROM ''0''
AND w_valocti.nb = 1
AND w_valocti.prestation_code IN (''ANT'', ''NN1'', ''SRC'', ''STF'', ''REA'')
', i_schema, v_annee, v_annee);
-- Report des montants sur transport si qu'une seule prestation transport dans le séjour
EXECUTE FORMAT ('
UPDATE %I.p_rsf_detail
SET
prix_unitaire = round(mnt_trans / coeftrans / coefrep,2),
coefficient_mco = round(w_valosej.coefrep * w_valosej.coeftrans * w_valosej.coefp,4),
base_remboursement = mnt_trans,
base_remboursement_sauf_transition = round(mnt_trans / coeftrans,2),
sejour_remboursable = mnt_trans_am
FROM
w_valosej
JOIN w_valocti ON w_valocti.rss_id = w_valosej.rss_id
WHERE 1=1
AND p_rsf_detail.rss_id = w_valocti.rss_id
AND p_rsf_detail.prestation_id = w_valocti.prestation_id
AND p_rsf_detail.est_ligne_rss IS DISTINCT FROM ''0''
AND w_valocti.nb = 1
AND w_valocti.prestation_code IN (''TDE1'',''TDE2'',''TDE3'',''TDE4'',''TDE5'',''TSE6'',''TSE7'',''TSE8'',''TSE9'')
', i_schema);
RAISE NOTICE '% | REPORT DES MONTANTS', to_char(CURRENT_TIMESTAMP, 'YYYY-MM-DD HH24:MI:ss');
EXECUTE FORMAT ('
UPDATE %I.p_rsf_total SET
sejour_remboursable = COALESCE(subview.sejour_remboursable,0)
FROM
%I.p_rss
LEFT JOIN (
SELECT
rss_id,
SUM(p_rsf_detail.sejour_remboursable) as sejour_remboursable,
SUM(p_rsf_detail.base_remboursement_sauf_transition) as base_remboursement_sauf_transition
FROM
%I.p_rsf_detail
JOIN %I.p_rss ON p_rsf_detail.rss_id = p_rss.oid
WHERE 1=1
AND import_id = %s
AND p_rsf_detail.est_ligne_rss IS DISTINCT FROM ''0''
GROUP BY rss_id
) subview ON p_rss.oid = subview.rss_id
WHERE 1=1
AND import_id = %s
AND p_rsf_total.rss_id = p_rss.oid
', i_schema, i_schema, i_schema, i_schema, i_import_id, i_import_id);
-- sejour_remboursable des IVG valorisé
EXECUTE FORMAT ('
UPDATE %I.p_rsf_detail
SET
sejour_remboursable = w_valosej.mnt_ivg_am
FROM
w_valosej
,w_valocti
WHERE 1=1
AND w_valocti.rss_id = w_valosej.rss_id
AND p_rsf_detail.rss_id = w_valosej.rss_id
AND p_rsf_detail.prestation_id = w_valocti.prestation_id
AND w_valocti.prestation_code IN (''AMD'', ''AMF'', ''APD'', ''IMD'')
AND w_valosej.valo <> 0
', i_schema);
EXECUTE FORMAT ('
UPDATE %I.p_rss SET
traitement_epmsi = ''30''::text
FROM
w_valosej
WHERE 1=1
AND w_valosej.rss_id = p_rss.oid
AND import_id = %s
AND w_valosej.valo IN (1,5)
AND traitement_epmsi IS DISTINCT FROM ''30''::text
', i_schema, i_import_id);
EXECUTE FORMAT ('
UPDATE %I.p_vidhosp
SET motif_non_facturation_id = 0
FROM w_valosej
JOIN %I.p_rss ON w_valosej.rss_id = p_rss.oid AND p_rss.import_id = %s
WHERE w_valosej.valo = 5 AND
p_rss.oid = p_vidhosp.rss_id AND
p_vidhosp.motif_non_facturation_id <> 0
', i_schema, i_schema, i_import_id);
EXECUTE FORMAT ('
UPDATE %I.p_vidhosp
SET code_pec_id = t_pec.oid
FROM w_valosej
JOIN %I.p_rss ON w_valosej.rss_id = p_rss.oid AND p_rss.import_id = %s
JOIN base.t_pec ON t_pec.code = ''1''
WHERE w_valosej.valo = 5 AND
p_rss.oid = p_vidhosp.rss_id AND
p_vidhosp.code_pec_id <> t_pec.oid
', i_schema, i_schema, i_import_id);
-- Incohérence ctl_mt2a
EXECUTE FORMAT ('
UPDATE %I.p_ctl_mt2a
SET erreur_genrsa = ''A''
FROM w_valosej
JOIN %I.p_rss ON
w_valosej.rss_id = p_rss.oid AND
import_id = %s
WHERE p_ctl_mt2a.rss_id = p_rss.oid AND
valo IN (1,5) AND
erreur_genrsa = ''1''
', i_schema, i_schema, i_import_id);
EXECUTE FORMAT ('
UPDATE %I.p_ctl_mt2a
SET erreur_genrsa = ''B''
FROM w_valosej
JOIN %I.p_rss ON
w_valosej.rss_id = p_rss.oid AND
import_id = %s
WHERE p_ctl_mt2a.rss_id = p_rss.oid AND
valo IN (1,5) AND
erreur_genrsa = ''2''
', i_schema, i_schema, i_import_id);
EXECUTE FORMAT ('
UPDATE %I.p_ctl_mt2a
SET erreur_genrsa = ''C''
FROM w_valosej
JOIN %I.p_rss ON
w_valosej.rss_id = p_rss.oid AND
import_id = %s
WHERE p_ctl_mt2a.rss_id = p_rss.oid AND
valo IN (1,5) AND
erreur_genrsa = ''3''
', i_schema, i_schema, i_import_id);
EXECUTE FORMAT ('
UPDATE %I.p_rss SET
valorise_valosejace = ''1''::text
FROM w_valosej
WHERE 1=1
AND w_valosej.rss_id = p_rss.oid
AND import_id = %s
', i_schema, i_import_id);
RETURN 'OK';
END;