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.
 
 

2297 lines
84 KiB

return: text
lang: plpgsql
parameters:
p0:
type: text
name: i_valoace_path
p1:
type: text
name: i_schema
p2:
type: bigint
name: i_import_id
src: |
DECLARE
_col text; -- to keep column names in each iteration
_sqlcmd text;
_annee numeric; -- annee du fichier valoace
_owner text;
BEGIN
-- Récupération du propriétaire
SELECT login INTO _owner FROM base.cti_user_credentials();
RAISE NOTICE '% | TRAITEMENT DU FICHIER : %', to_char(CURRENT_TIMESTAMP, 'YYYY-MM-DD HH24:MI:ss'), i_valoace_path;
RAISE NOTICE '% | SCHEMA : %', to_char(CURRENT_TIMESTAMP, 'YYYY-MM-DD HH24:MI:ss'), i_schema;
RAISE NOTICE '% | IMPORT : %', to_char(CURRENT_TIMESTAMP, 'YYYY-MM-DD HH24:MI:ss'), i_import_id;
/* *************************************
Pré-chargement pour nom des colonnes
****************************************/
DROP TABLE IF EXISTS in_valoace CASCADE;
DROP SEQUENCE IF EXISTS s_valoace;
CREATE TEMP SEQUENCE s_valoace;
CREATE TEMP TABLE in_valoace (
ligne numeric DEFAULT nextval('s_valoace'::regclass),
data text,
data_array text[]
);
_sqlcmd = 'COPY in_valoace (data) FROM ''' || i_valoace_path || ''' WITH delimiter ''²''';
EXECUTE _sqlcmd;
UPDATE in_valoace
SET data = replace(data,'seqmcoraf', 'noent')
WHERE ligne = 1;
DELETE FROM in_valoace where ligne > 1;
UPDATE in_valoace SET data_array = string_to_array(data,chr(9));
ALTER TABLE in_valoace DROP COLUMN "data";
/* ***********************************
Peuplement de la table valoace
**************************************/
DROP TABLE IF EXISTS temp_table;
CREATE TEMP TABLE temp_table ();
-- Ajout des colonnes avec le bon nom
FOR _col IN (SELECT UNNEST(data_array) from in_valoace)
LOOP
EXECUTE FORMAT ('ALTER TABLE temp_table ADD COLUMN %s text;', _col);
END LOOP;
-- copy the data from csv file
EXECUTE FORMAT ('COPY temp_table FROM %L WITH DELIMITER E''\t'' CSV HEADER', i_valoace_path);
DROP SEQUENCE IF EXISTS s_temp_table;
CREATE TEMP SEQUENCE s_temp_table;
ALTER TABLE temp_table ADD COLUMN no_ligne bigint;
UPDATE temp_table SET
no_ligne = nextval('s_temp_table'::regclass);
UPDATE temp_table SET
noent = trim(leading '0' FROM trim(noent));
DROP TABLE IF EXISTS temp.p_valoace;
CREATE TABLE temp.p_valoace AS
SELECT *,
row_number() OVER (PARTITION BY noent ORDER BY no_ligne) AS sequence_facture
FROM temp_table
;
ALTER TABLE temp.p_valoace ADD COLUMN rss_id bigint DEFAULT 0;
ALTER TABLE temp.p_valoace ADD COLUMN no_rss bigint DEFAULT 0;
-- Nouvelle verison 2023
-- Colonne noent = no_sejour@no_facture
EXECUTE FORMAT ('
UPDATE temp.p_valoace SET
rss_id = subview.rss_id,
no_rss = subview.no_rss
FROM
(
SELECT base.cti_to_number(no_facture) AS no_facture, rss_id, p_rsf_total.no_rss,
row_number() OVER (PARTITION BY no_facture ORDER BY no_ligne) AS sequence_facture
FROM %I.p_rsf_total
JOIN %I.p_rss ON p_rsf_total.rss_id = p_rss.oid
WHERE p_rss.import_id = %s AND
p_rsf_total.no_facture <> '''' AND
base.cti_to_number(no_facture) <> 0
) subview
WHERE p_valoace.noent LIKE ''%%@%%'' AND
base.cti_to_number(split_part(p_valoace.noent,''@'',2)) = subview.no_facture AND
p_valoace.sequence_facture = subview.sequence_facture;
', i_schema, i_schema, i_import_id);
-- Ancienne verison
-- Colonne noent = no_facture
EXECUTE FORMAT ('
UPDATE temp.p_valoace SET
rss_id = subview.rss_id,
no_rss = subview.no_rss
FROM
(
SELECT base.cti_to_number(no_facture) AS no_facture, rss_id, p_rsf_total.no_rss,
row_number() OVER (PARTITION BY no_facture ORDER BY no_ligne) AS sequence_facture
FROM %I.p_rsf_total
JOIN %I.p_rss ON p_rsf_total.rss_id = p_rss.oid
WHERE p_rss.import_id = %s AND
p_rsf_total.no_facture <> '''' AND
base.cti_to_number(no_facture) <> 0
) subview
WHERE p_valoace.noent NOT LIKE ''%%@%%'' AND
base.cti_to_number(p_valoace.noent) = subview.no_facture AND
p_valoace.sequence_facture = subview.sequence_facture
;
', i_schema, i_schema, i_import_id);
-- Controle cohérence VALOACE
DROP TABLE IF EXISTS w_valoace_ko;
CREATE TEMP TABLE w_valoace_ko AS
SELECT '1'::text, count(*) AS nb
FROM temp.p_valoace
WHERE rss_id = 0
;
EXECUTE FORMAT ('
INSERT INTO w_valoace_ko
SELECT ''2''::text, count(*) AS nb
FROM %I.p_rsf_total
JOIN %I.p_rss on rss_id = p_rss.oid
WHERE import_id = %s AND ghm_id = 0 AND
trim(no_facture) <> '''' AND
rss_id NOT IN (SELECT rss_id FROM temp.p_valoace)
;
', i_schema, i_schema, i_import_id);
IF (SELECT SUM(nb) FROM w_valoace_ko) > 10 THEN
return 'KO. Fichier VALOSEJ semble incohérent';
END IF;
DROP TABLE IF EXISTS pmsi.p_valoace;
CREATE TABLE pmsi.p_valoace
(
rss_id bigint,
no_rss bigint,
finess text,
noent bigint,
valo text,
fides text,
fides_ovalide text,
nbligne numeric,
sej_fact text,
motif_nonf text,
tmf text,
mnt_br_atu numeric,
mnt_br_ffm numeric,
mnt_br_dia numeric,
mnt_br_se numeric,
mnt_br_ftn numeric,
mnt_br_ngap numeric,
mnt_br_ccam numeric,
mnt_br_pi numeric,
mnt_br_dm_ext numeric,
mnt_br_med_ext numeric,
mnt_br_i04 numeric,
mnt_br_mop numeric,
mnt_br numeric,
mnt_remb_atu numeric,
mnt_remb_ffm numeric,
mnt_remb_dia numeric,
mnt_remb_se numeric,
mnt_remb_ftn numeric,
mnt_remb_ccam numeric,
mnt_remb_pi numeric,
mnt_remb_dm_ext numeric,
mnt_remb_med_ext numeric,
mnt_remb_i04 numeric,
mnt_remb_mop numeric,
mnt_val_atu numeric,
mnt_val_ffm numeric,
mnt_val_se numeric,
mnt_val_ftn numeric,
mnt_val_ngap numeric,
mnt_val_ccam numeric,
mnt_val_pi numeric,
mnt_val_dm_ext numeric,
mnt_val_med_ext numeric,
mnt_val_i04 numeric,
mnt_val numeric,
mnt_rac numeric,
no_ligne bigint,
pf18 numeric
);
-- Evaluation variable _owner nécessaire
EXECUTE 'ALTER TABLE pmsi.p_valoace OWNER TO ' || _owner;
DROP TABLE temp_table;
DROP TABLE in_valoace;
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_valoace', 'fides', 'text');
PERFORM base.cti_add_column_if_not_exists('temp.p_valoace', 'fides_ovalide', 'text');
PERFORM base.cti_add_column_if_not_exists('temp.p_valoace', 'nbligne', 'text');
PERFORM base.cti_add_column_if_not_exists('temp.p_valoace', 'sej_fact', 'text');
PERFORM base.cti_add_column_if_not_exists('temp.p_valoace', 'motif_nonf', 'text');
PERFORM base.cti_add_column_if_not_exists('temp.p_valoace', 'pf18', 'text');
PERFORM base.cti_add_column_if_not_exists('temp.p_valoace', 'mnt_br_atu', 'text');
PERFORM base.cti_add_column_if_not_exists('temp.p_valoace', 'mnt_br_ffm', 'text');
PERFORM base.cti_add_column_if_not_exists('temp.p_valoace', 'mnt_br_dia', 'text');
PERFORM base.cti_add_column_if_not_exists('temp.p_valoace', 'mnt_br_se', 'text');
PERFORM base.cti_add_column_if_not_exists('temp.p_valoace', 'mnt_br_ftn', 'text');
PERFORM base.cti_add_column_if_not_exists('temp.p_valoace', 'mnt_br_ngap', 'text');
PERFORM base.cti_add_column_if_not_exists('temp.p_valoace', 'mnt_br_ccam', 'text');
PERFORM base.cti_add_column_if_not_exists('temp.p_valoace', 'mnt_br_pi', 'text');
PERFORM base.cti_add_column_if_not_exists('temp.p_valoace', 'mnt_br_dm_ext', 'text');
PERFORM base.cti_add_column_if_not_exists('temp.p_valoace', 'mnt_br_med_ext', 'text');
PERFORM base.cti_add_column_if_not_exists('temp.p_valoace', 'mnt_br_i04', 'text');
PERFORM base.cti_add_column_if_not_exists('temp.p_valoace', 'mnt_br_mop', 'text');
PERFORM base.cti_add_column_if_not_exists('temp.p_valoace', 'mnt_br', 'text');
PERFORM base.cti_add_column_if_not_exists('temp.p_valoace', 'mnt_remb_atu', 'text');
PERFORM base.cti_add_column_if_not_exists('temp.p_valoace', 'mnt_remb_ffm', 'text');
PERFORM base.cti_add_column_if_not_exists('temp.p_valoace', 'mnt_remb_dia', 'text');
PERFORM base.cti_add_column_if_not_exists('temp.p_valoace', 'mnt_remb_se', 'text');
PERFORM base.cti_add_column_if_not_exists('temp.p_valoace', 'mnt_remb_ftn', 'text');
PERFORM base.cti_add_column_if_not_exists('temp.p_valoace', 'mnt_remb_ngap', 'text');
PERFORM base.cti_add_column_if_not_exists('temp.p_valoace', 'mnt_remb_ccam', 'text');
PERFORM base.cti_add_column_if_not_exists('temp.p_valoace', 'mnt_remb_pi', 'text');
PERFORM base.cti_add_column_if_not_exists('temp.p_valoace', 'mnt_remb_dm_ext', 'text');
PERFORM base.cti_add_column_if_not_exists('temp.p_valoace', 'mnt_remb_med_ext', 'text');
PERFORM base.cti_add_column_if_not_exists('temp.p_valoace', 'mnt_remb_i04', 'text');
PERFORM base.cti_add_column_if_not_exists('temp.p_valoace', 'mnt_remb_mop', 'text');
PERFORM base.cti_add_column_if_not_exists('temp.p_valoace', 'mnt_remb', 'text');
PERFORM base.cti_add_column_if_not_exists('temp.p_valoace', 'mnt_val_atu', 'text');
PERFORM base.cti_add_column_if_not_exists('temp.p_valoace', 'mnt_val_ffm', 'text');
PERFORM base.cti_add_column_if_not_exists('temp.p_valoace', 'mnt_val_dia', 'text');
PERFORM base.cti_add_column_if_not_exists('temp.p_valoace', 'mnt_val_se', 'text');
PERFORM base.cti_add_column_if_not_exists('temp.p_valoace', 'mnt_val_ftn', 'text');
PERFORM base.cti_add_column_if_not_exists('temp.p_valoace', 'mnt_val_ngap', 'text');
PERFORM base.cti_add_column_if_not_exists('temp.p_valoace', 'mnt_val_ccam', 'text');
PERFORM base.cti_add_column_if_not_exists('temp.p_valoace', 'mnt_val_pi', 'text');
PERFORM base.cti_add_column_if_not_exists('temp.p_valoace', 'mnt_val_dm_ext', 'text');
PERFORM base.cti_add_column_if_not_exists('temp.p_valoace', 'mnt_val_med_ext', 'text');
PERFORM base.cti_add_column_if_not_exists('temp.p_valoace', 'mnt_val_i04', 'text');
PERFORM base.cti_add_column_if_not_exists('temp.p_valoace', 'mnt_val_mop', 'text');
PERFORM base.cti_add_column_if_not_exists('temp.p_valoace', 'mnt_val', 'text');
PERFORM base.cti_add_column_if_not_exists('temp.p_valoace', 'mnt_rac', 'text');
PERFORM base.cti_add_column_if_not_exists('temp.p_valoace', 'tmf', 'text');
-- COLLECTE DES INFOS DE VALORISATION VALOACE
DROP TABLE IF EXISTS w_ace;
CREATE TEMP TABLE w_ace AS
SELECT
p_valoace.rss_id,
p_valoace.no_rss,
p_valoace.noent as noent
,p_valoace.no_ligne as no_ligne
,row_number() OVER (PARTITION BY noent ORDER BY p_valoace.no_ligne) AS sequence_facture
,base.cti_to_number(p_valoace.valo) as valo
,p_valoace.fides as fides
,CASE WHEN fides_ovalide = '1' THEN 1 ELSE 0 END as fides_ovalide
,base.cti_to_number(p_valoace.nbligne) as nbligne
,p_valoace.sej_fact as sej_fact
,p_valoace.motif_nonf as motif_nonf
,p_valoace.pf18 as pf18
,p_valoace.tmf as tmf
,base.cti_to_number(p_valoace.mnt_br_atu) as mnt_br_atu
,base.cti_to_number(p_valoace.mnt_br_ffm) as mnt_br_ffm
,base.cti_to_number(p_valoace.mnt_br_dia) as mnt_br_dia
,base.cti_to_number(p_valoace.mnt_br_se) as mnt_br_se
,base.cti_to_number(p_valoace.mnt_br_ftn) as mnt_br_ftn
,base.cti_to_number(p_valoace.mnt_br_ngap) as mnt_br_ngap
,base.cti_to_number(p_valoace.mnt_br_ccam) as mnt_br_ccam
,base.cti_to_number(p_valoace.mnt_br_pi) as mnt_br_pi
,base.cti_to_number(p_valoace.mnt_br_dm_ext) as mnt_br_dm_ext
,base.cti_to_number(p_valoace.mnt_br_med_ext) as mnt_br_med_ext
,base.cti_to_number(p_valoace.mnt_br_i04) as mnt_br_i04
,base.cti_to_number(p_valoace.mnt_br_mop) as mnt_br_mop
,base.cti_to_number(p_valoace.mnt_br) as mnt_br
,base.cti_to_number(p_valoace.mnt_remb_atu) as mnt_remb_atu
,base.cti_to_number(p_valoace.mnt_remb_ffm) as mnt_remb_ffm
,base.cti_to_number(p_valoace.mnt_remb_dia) as mnt_remb_dia
,base.cti_to_number(p_valoace.mnt_remb_se) as mnt_remb_se
,base.cti_to_number(p_valoace.mnt_remb_ftn) as mnt_remb_ftn
,base.cti_to_number(p_valoace.mnt_remb_ngap) as mnt_remb_ngap
,base.cti_to_number(p_valoace.mnt_remb_ccam) as mnt_remb_ccam
,base.cti_to_number(p_valoace.mnt_remb_pi) as mnt_remb_pi
,base.cti_to_number(p_valoace.mnt_remb_dm_ext) as mnt_remb_dm_ext
,base.cti_to_number(p_valoace.mnt_remb_med_ext) as mnt_remb_med_ext
,base.cti_to_number(p_valoace.mnt_remb_i04) as mnt_remb_i04
,base.cti_to_number(p_valoace.mnt_remb_mop) as mnt_remb_mop
,base.cti_to_number(p_valoace.mnt_remb) as mnt_remb
FROM
temp.p_valoace
;
-- Correction traitement epmsi
EXECUTE FORMAT ('
UPDATE %I.p_rss SET
traitement_epmsi = ''24''
FROM w_ace
WHERE 1=1
AND w_ace.rss_id = p_rss.oid
AND p_rss.traitement_epmsi = ''30''
AND valo NOT IN (''1'',''2'',''3'');
', i_schema);
EXECUTE FORMAT ('
UPDATE %I.p_rss SET
traitement_epmsi = ''24''
FROM %I.p_rsf_total
WHERE p_rsf_total.rss_id = p_rss.oid AND
p_rss.import_id = %s AND
p_rss.oid NOT IN (SELECT rss_id FROM w_ace) AND
trim(p_rsf_total.no_facture) <> '''' AND
p_rss.traitement_epmsi = ''30'';
;
', i_schema, i_schema, i_import_id);
EXECUTE FORMAT ('
UPDATE %I.p_rss SET
traitement_epmsi = ''30''
FROM w_ace
WHERE 1=1
AND w_ace.rss_id = p_rss.oid
AND p_rss.traitement_epmsi <> ''30''
AND valo IN (''1'',''2'',''3'');
', i_schema);
UPDATE w_ace SET
mnt_br_ngap = mnt_br_ngap + 24,
mnt_remb_ngap = mnt_remb_ngap + 24
WHERE tmf = '1' AND
valo IN ('1','2','3')
;
-- Correction valorise FIDES
EXECUTE FORMAT ('
UPDATE %I.p_rsf_total SET
valorise_fides = w_ace.fides_ovalide
FROM
w_ace
WHERE 1=1
AND w_ace.rss_id = p_rsf_total.rss_id
AND p_rsf_total.valorise_fides IS DISTINCT FROM w_ace.fides_ovalide;
', i_schema);
CREATE INDEX i_w_ace_1 ON w_ace USING btree (rss_id);
-- Type de prestation ACE
DROP TABLE IF EXISTS w_prestations;
EXECUTE FORMAT ('
CREATE TEMP TABLE w_prestations AS
SELECT t_prestations.oid,
t_prestations.code,
t_prestations.texte,
MAX(p_rsf_detail.type) AS type_prestation_rsf,
''''::text AS type_prestation_ace
FROM %I.p_rsf_detail
JOIN %I.p_rss ON rss_id = p_rss.oid
JOIN pmsi.t_prestations ON prestation_id = t_prestations.oid
WHERE ghm_id = 0 AND
import_id = %s AND
prestation_id > 0
GROUP BY 1,2,3;
', i_schema, i_schema, i_import_id)
;
EXECUTE FORMAT ('
INSERT INTO w_prestations
SELECT t_prestations.oid,
t_prestations.code,
t_prestations.texte,
MAX(p_rsf_detail.type) AS type_prestation_rsf,
''''::text AS type_prestation_ace
FROM %I.p_rsf_detail_non_valorise p_rsf_detail
JOIN %I.p_rss ON rss_id = p_rss.oid
JOIN pmsi.t_prestations ON prestation_id = t_prestations.oid
WHERE ghm_id = 0 AND
import_id = %s AND
prestation_id > 0 AND
prestation_id NOT IN (SELECT w_prestations.oid FROM w_prestations)
GROUP BY 1,2,3;
', i_schema, i_schema, i_import_id)
;
UPDATE w_prestations SET
type_prestation_ace =
CASE
WHEN code LIKE 'SE%' THEN 'SE'
WHEN oid IN (SELECT prestation_defaut_id FROM pmsi.t_lpp) THEN 'DMI'
WHEN code LIKE 'D1%' THEN 'DIA'
WHEN code LIKE 'D2%' THEN 'DIA'
WHEN code LIKE 'FTN%' THEN 'FTN'
WHEN code LIKE 'FTR%' THEN 'FTR'
WHEN code LIKE 'ATU%' THEN 'ATU'
WHEN code LIKE 'FFM%' THEN 'FFM'
WHEN code LIKE 'MOPHNG' THEN 'MOP'
WHEN code LIKE 'FPI%' THEN 'FPI'
WHEN code LIKE 'AP2%' THEN 'MED'
WHEN code LIKE 'PAT%' THEN 'PAT'
WHEN code LIKE 'PAE%' THEN 'PAT'
WHEN type_prestation_rsf = 'C' AND code IN ('ACO', 'ADA', 'ADC', 'ADE', 'ADI', 'ATM', 'DEN') THEN 'CCAM'
WHEN type_prestation_rsf = 'C' THEN 'NGAP'
WHEN type_prestation_rsf = 'B' THEN 'NGAP'
ELSE '' END
;
-- Transformation des taux pour les détenus
EXECUTE FORMAT ('
UPDATE %I.p_rsf_detail SET
taux_remboursement = subview.taux_remboursement,
sejour_remboursable = round(base_remboursement*subview.taux_remboursement,2)/100.00
FROM
(
SELECT
p_rsf_detail.rss_id,
prestation_id,
t_prestations.code,
CASE
WHEN type_prestation_ace = ''ATU'' THEN base.cti_division(mnt_remb_atu,mnt_br_atu)*100
WHEN type_prestation_ace = ''NGAP'' THEN base.cti_division(mnt_remb_ngap,mnt_br_ngap)*100
WHEN type_prestation_ace = ''CCAM'' THEN base.cti_division(mnt_remb_ccam,mnt_br_ccam)*100
ELSE p_rsf_detail.taux_remboursement END AS taux_remboursement
FROM %I.p_rsf_detail
JOIN w_ace ON w_ace.rss_id = p_rsf_detail.rss_id
JOIN w_prestations t_prestations ON prestation_id = t_prestations.oid
WHERE valo = 3
) subview
WHERE p_rsf_detail.rss_id = subview.rss_id AND
p_rsf_detail.prestation_id = subview.prestation_id AND
p_rsf_detail.taux_remboursement <> subview.taux_remboursement
', i_schema, i_schema);
-- COLLECTE DES INFOS DE VALORISATION CTI
DROP TABLE IF EXISTS w_cti;
EXECUTE FORMAT ('
CREATE TEMP TABLE w_cti as
SELECT
p_rss.finess,
p_rss.no_sejour_administratif
,p_rss.no_rss
,p_rss.oid as rss_id
,traitement_epmsi
,COALESCE(p_rsf_total.valorise_fides, 0) as valorise_fides
,p_rss.date_sortie
,CASE
WHEN p_rss.date_sortie BETWEEN ''20130301'' AND ''20160229'' THEN 0.9965
WHEN p_rss.date_sortie BETWEEN ''20160301'' AND ''20170228'' THEN 0.9950
WHEN p_rss.date_sortie BETWEEN ''20170301'' AND ''20991231'' THEN 0.9930
ELSE 1 END::numeric AS coef_prud
,rank() over(order by p_rsf_total.no_ligne) as no_ligne
,row_number() OVER(PARTITION BY p_rsf_total.no_facture ORDER BY p_rsf_total.no_ligne) as sequence_facture
,count(*) as nb_lignes
,SUM(CASE WHEN type_prestation_ace = ''SE'' THEN p_rsf_detail.nombre ELSE 0 END) AS cti_nb_se
,SUM(CASE WHEN type_prestation_ace = ''SE'' THEN p_rsf_detail.base_remboursement ELSE 0 END) AS cti_br_se
,SUM(CASE WHEN type_prestation_ace = ''SE'' THEN p_rsf_detail.base_remboursement_sauf_transition ELSE 0 END) AS cti_brht_se
,SUM(CASE WHEN type_prestation_ace = ''SE'' THEN p_rsf_detail.sejour_remboursable ELSE 0 END) AS cti_remb_se
,SUM(CASE WHEN type_prestation_ace = ''DIA'' THEN p_rsf_detail.nombre ELSE 0 END) AS cti_nb_dia
,SUM(CASE WHEN type_prestation_ace = ''DIA'' THEN p_rsf_detail.base_remboursement ELSE 0 END) AS cti_br_dia
,SUM(CASE WHEN type_prestation_ace = ''DIA'' THEN p_rsf_detail.sejour_remboursable ELSE 0 END) AS cti_remb_dia
,SUM(CASE WHEN type_prestation_ace = ''ATU'' THEN p_rsf_detail.nombre ELSE 0 END) AS cti_nb_atu
,SUM(CASE WHEN type_prestation_ace = ''ATU'' THEN p_rsf_detail.base_remboursement ELSE 0 END) AS cti_br_atu
,SUM(CASE WHEN type_prestation_ace = ''ATU'' THEN p_rsf_detail.sejour_remboursable ELSE 0 END) AS cti_remb_atu
,SUM(CASE WHEN type_prestation_ace = ''FFM'' THEN p_rsf_detail.nombre ELSE 0 END) AS cti_nb_ffm
,SUM(CASE WHEN type_prestation_ace = ''FFM'' THEN p_rsf_detail.base_remboursement ELSE 0 END) AS cti_br_ffm
,SUM(CASE WHEN type_prestation_ace = ''FFM'' THEN p_rsf_detail.sejour_remboursable ELSE 0 END) AS cti_remb_ffm
,SUM(CASE WHEN type_prestation_ace = ''MOPHNG'' THEN p_rsf_detail.nombre ELSE 0 END) AS cti_nb_mop
,SUM(CASE WHEN type_prestation_ace = ''MOPHNG'' THEN p_rsf_detail.base_remboursement ELSE 0 END) AS cti_br_mop
,SUM(CASE WHEN type_prestation_ace = ''MOPHNG'' THEN p_rsf_detail.sejour_remboursable ELSE 0 END) AS cti_remb_mop
,SUM(CASE WHEN type_prestation_ace = ''FTN'' THEN p_rsf_detail.nombre ELSE 0 END) AS cti_nb_ftn
,SUM(CASE WHEN type_prestation_ace = ''FTN'' THEN p_rsf_detail.base_remboursement ELSE 0 END) AS cti_br_ftn
,SUM(CASE WHEN type_prestation_ace = ''FTN'' THEN p_rsf_detail.sejour_remboursable ELSE 0 END) AS cti_remb_ftn
,SUM(CASE WHEN type_prestation_ace = ''FPI'' THEN p_rsf_detail.nombre ELSE 0 END) AS cti_nb_fpi
,SUM(CASE WHEN type_prestation_ace = ''FPI'' THEN p_rsf_detail.base_remboursement ELSE 0 END) AS cti_br_fpi
,SUM(CASE WHEN type_prestation_ace = ''FPI'' THEN p_rsf_detail.sejour_remboursable ELSE 0 END) AS cti_remb_fpi
,SUM(CASE WHEN type_prestation_ace = ''DMI'' THEN p_rsf_detail.nombre ELSE 0 END) AS cti_nb_dm_ext
,SUM(CASE WHEN type_prestation_ace = ''DMI'' THEN p_rsf_detail.base_remboursement ELSE 0 END) AS cti_br_dm_ext
,SUM(CASE WHEN type_prestation_ace = ''DMI'' THEN p_rsf_detail.sejour_remboursable ELSE 0 END) AS cti_remb_dm_ext
,SUM(CASE WHEN type_prestation_ace = ''AP2'' THEN p_rsf_detail.nombre ELSE 0 END) AS cti_nb_med
,SUM(CASE WHEN type_prestation_ace = ''AP2'' THEN p_rsf_detail.base_remboursement ELSE 0 END) AS cti_br_med
,SUM(CASE WHEN type_prestation_ace = ''AP2'' THEN p_rsf_detail.sejour_remboursable ELSE 0 END) AS cti_remb_med
,SUM(CASE WHEN type_prestation_ace = ''CCAM'' THEN p_rsf_detail.nombre ELSE 0 END) AS cti_nb_ccam
,SUM(CASE WHEN type_prestation_ace = ''CCAM'' THEN p_rsf_detail.base_remboursement ELSE 0 END) AS cti_br_ccam
,SUM(CASE WHEN type_prestation_ace = ''CCAM'' THEN p_rsf_detail.sejour_remboursable ELSE 0 END) AS cti_remb_ccam
,SUM(CASE WHEN type_prestation_ace = ''NGAP'' THEN p_rsf_detail.nombre ELSE 0 END) AS cti_nb_ngap
,SUM(CASE WHEN type_prestation_ace = ''NGAP'' THEN p_rsf_detail.base_remboursement ELSE 0 END) AS cti_br_ngap
,SUM(CASE WHEN type_prestation_ace = ''NGAP'' THEN p_rsf_detail.sejour_remboursable ELSE 0 END) AS cti_remb_ngap
,round(SUM(CASE WHEN type_prestation_ace = ''NGAP'' THEN p_rsf_detail.sejour_remboursable ELSE 0 END * CASE WHEN p_rsf_detail.taux_remboursement <> 100 THEN base.cti_division(80::numeric , p_rsf_detail.taux_remboursement) ELSE 1 END ),2) AS cti_remb_ngap_ajuste80
FROM
%I.p_rss
LEFT JOIN %I.p_rsf_total ON p_rss.oid = p_rsf_total.rss_id
LEFT JOIN %I.p_rsf_detail ON p_rsf_detail.rss_id = p_rsf_total.rss_id
LEFT JOIN w_prestations t_prestations ON t_prestations.oid = p_rsf_detail.prestation_id
WHERE 1=1
AND ghm_id = 0
AND est_ligne_rss IS DISTINCT FROM ''0''
AND t_prestations.code IS DISTINCT FROM ''PAT''
AND p_rss.import_id = %s
GROUP BY
p_rss.finess,
p_rss.no_sejour_administratif,
p_rss.no_rss, p_rss.oid,
p_rsf_total.no_ligne,
p_rsf_total.no_facture,
traitement_epmsi,
p_rsf_total.valorise_fides,
p_rss.date_sortie;
', i_schema, i_schema, i_schema, i_import_id);
CREATE INDEX i_w_cti_1 ON w_cti USING btree (rss_id);
-- Ajustement de taux bizarres
EXECUTE FORMAT ('
UPDATE %I.p_rsf_detail SET
taux_remboursement = subview.taux_remboursement,
sejour_remboursable = round(base_remboursement*subview.taux_remboursement,2)/100.00
FROM
(
SELECT
p_rsf_detail.rss_id,
prestation_id,
t_prestations.code,
80::numeric AS taux_remboursement
FROM %I.p_rsf_detail
JOIN w_ace ON w_ace.rss_id = p_rsf_detail.rss_id
JOIN w_cti ON w_cti.rss_id = p_rsf_detail.rss_id
JOIN w_prestations t_prestations ON prestation_id = t_prestations.oid
WHERE abs(mnt_remb_ngap - cti_remb_ngap) > 0.05 AND
abs(mnt_remb_ngap - cti_remb_ngap_ajuste80) <= 0.05 AND
type_prestation_ace = ''NGAP''
) subview
WHERE p_rsf_detail.rss_id = subview.rss_id AND
p_rsf_detail.prestation_id = subview.prestation_id AND
p_rsf_detail.taux_remboursement <> subview.taux_remboursement
;
UPDATE w_cti
SET cti_remb_ngap = cti_remb_ngap_ajuste80
FROM w_ace
WHERE w_ace.rss_id = w_cti.rss_id AND
abs(mnt_remb_ngap - cti_remb_ngap) > 0.05 AND
abs(mnt_remb_ngap - cti_remb_ngap_ajuste80) <= 0.05
', i_schema, i_schema)
;
---------------------
-- Traitement des FFM
---------------------
-- Arrondis + ecarts sur dernier dossier
UPDATE w_ace SET
mnt_br_ffm = round(mnt_br_ffm + ecart_br,2),
mnt_remb_ffm = round(mnt_remb_ffm + ecart_remb,2)
FROM
(
SELECT w_ace.rss_id, row_number() OVER (ORDER BY rss_id),
CASE WHEN row_number() OVER (ORDER BY rss_id) <= nb_ecart_br THEN ecart_br ELSE 0 END AS ecart_br,
CASE WHEN row_number() OVER (ORDER BY rss_id) <= nb_ecart_remb THEN ecart_remb ELSE 0 END AS ecart_remb
FROM w_ace
JOIN
(
SELECT round((SUM(mnt_remb_ffm) - SUM(round(w_ace.mnt_remb_ffm,2))),2),
CASE WHEN round((SUM(mnt_br_ffm) - SUM(round(w_ace.mnt_br_ffm,2)))*100,0) >= 0 THEN 0.01 ELSE -0.01 END AS ecart_br,
CASE WHEN round((SUM(mnt_remb_ffm) - SUM(round(w_ace.mnt_remb_ffm,2)))*100,0) >= 0 THEN 0.01 ELSE -0.01 END AS ecart_remb,
abs(round((SUM(mnt_br_ffm) - SUM(round(w_ace.mnt_br_ffm,2)))*100,0)) AS nb_ecart_br,
abs(round((SUM(mnt_remb_ffm) - SUM(round(w_ace.mnt_remb_ffm,2)))*100,0)) AS nb_ecart_remb
FROM w_ace
WHERE valo IN ('1','2','3') AND
(mnt_br_ffm <> 0 OR mnt_remb_ffm <> 0)
) subview ON valo IN ('1','2','3') AND
(mnt_br_ffm <> 0 OR mnt_remb_ffm <> 0)
ORDER BY rss_id
) subview
WHERE w_ace.rss_id = subview.rss_id AND
valo IN ('1','2','3') AND
(
mnt_br_ffm IS DISTINCT FROM round(mnt_br_ffm + ecart_br,2) OR
mnt_remb_ffm IS DISTINCT FROM round(mnt_remb_ffm + ecart_remb,2)
)
;
-- Report des montants sur RSF
EXECUTE FORMAT ('
UPDATE %I.p_rsf_detail SET
base_remboursement = round(w_ace.mnt_br_ffm,2),
sejour_remboursable = round(w_ace.mnt_remb_ffm,2)
FROM w_ace, w_prestations t_prestations
WHERE w_ace.rss_id = p_rsf_detail.rss_id AND
prestation_id = t_prestations.oid AND
type_prestation_ace = ''FFM'' AND
valo IN (''1'',''2'',''3'') AND
(
round(w_ace.mnt_br_ffm,2) <> base_remboursement OR
round(w_ace.mnt_remb_ffm,2) <> sejour_remboursable
)
;
', i_schema)
;
---------------------
-- Traitement des ATU
---------------------
-- Suppression de lignes non valorisées si créées à tord (selon ecart cti/ace)
EXECUTE FORMAT ('
DROP TABLE IF EXISTS w_rsf_detail_non_valorise;
CREATE TEMP TABLE w_rsf_detail_non_valorise AS
SELECT w_cti.rss_id AS nv_rss_id,
p_rsf_detail.CTID AS nv_CTID,
p_rsf_detail.nombre AS nv_nombre,
p_rsf_detail.base_remboursement AS nv_base_remboursement,
p_rsf_detail.sejour_remboursable AS nv_sejour_remboursable,
t_prestations.code AS nv_prestation_code
FROM w_cti
JOIN w_ace ON w_cti.rss_id = w_ace.rss_id
JOIN %I.p_rsf_detail ON w_cti.rss_id = p_rsf_detail.rss_id AND est_ligne_rss IS DISTINCT FROM ''0''
JOIN w_prestations t_prestations On prestation_id = t_prestations.oid
WHERE mnt_br_atu = 0 AND
valo IN (''1'',''2'',''3'') AND
p_rsf_detail.type = ''B'' AND
type_prestation_ace = ''ATU''
;
', i_schema);
EXECUTE FORMAT ('
INSERT INTO %I.p_rsf_detail_non_valorise(
finess,
no_rss,
nature,
mt,
dmt,
date_debut,
date_fin,
nombre,
coefficient,
prix_unitaire,
base_remboursement,
taux_remboursement,
sejour_facture,
sejour_remboursable,
compteur,
ligne_t2a,
pec_fj,
coefficient_mco,
sejour_remboursable_2,
ghs_id,
sejour_rembourse_noemie,
nature_noemie,
prestation_id,
rss_id,
type,
coefficient_geo,
est_ligne_rss,
est_ligne_rum,
no_rum,
unite_medicale_id,
base_remboursement_rum,
montant_supplement_nf,
sejour_remboursable_rum,
pec_fj_id,
base_remboursement_sauf_transition,
base_remboursement_rum_sauf_transition,
regle,
regle_id,
coefficient_pacte_resp,
no_ligne
)
SELECT
finess,
no_rss,
nature,
mt,
dmt,
date_debut,
date_fin,
nombre,
coefficient,
prix_unitaire,
base_remboursement,
taux_remboursement,
sejour_facture,
sejour_remboursable,
compteur,
ligne_t2a,
pec_fj,
coefficient_mco,
sejour_remboursable_2,
ghs_id,
sejour_rembourse_noemie,
nature_noemie,
prestation_id,
rss_id,
type,
coefficient_geo,
est_ligne_rss,
est_ligne_rum,
no_rum,
unite_medicale_id,
base_remboursement_rum,
montant_supplement_nf,
sejour_remboursable_rum,
pec_fj_id,
base_remboursement_sauf_transition,
base_remboursement_rum_sauf_transition,
0::bigint AS regle,
0::bigint AS regle_id,
coefficient_pacte_resp,
no_ligne
FROM %I.p_rsf_detail
JOIN w_rsf_detail_non_valorise ON
rss_id = nv_rss_id AND
p_rsf_detail.CTID = nv_CTID
;
', i_schema, i_schema);
EXECUTE FORMAT ('
DELETE FROM %I.p_rsf_detail
USING w_rsf_detail_non_valorise
WHERE rss_id = nv_rss_id AND
p_rsf_detail.CTID = nv_CTID
', i_schema);
UPDATE w_cti SET
cti_nb_se = cti_nb_se - nv_nombre,
cti_br_se = cti_br_se - nv_base_remboursement,
cti_remb_se = cti_remb_se - nv_sejour_remboursable
FROM w_rsf_detail_non_valorise
WHERE rss_id = nv_rss_id
;
-- Arrondis
UPDATE w_ace SET
mnt_br_atu = round(mnt_br_atu + ecart_br,2),
mnt_remb_atu = round(mnt_remb_atu + ecart_remb,2)
FROM
(
SELECT w_ace.rss_id, row_number() OVER (ORDER BY rss_id),
CASE WHEN row_number() OVER (ORDER BY rss_id) <= nb_ecart_br THEN ecart_br ELSE 0 END AS ecart_br,
CASE WHEN row_number() OVER (ORDER BY rss_id) <= nb_ecart_remb THEN ecart_remb ELSE 0 END AS ecart_remb
FROM w_ace
JOIN
(
SELECT round((SUM(mnt_remb_atu) - SUM(round(w_ace.mnt_remb_atu,2))),2),
CASE WHEN round((SUM(mnt_br_atu) - SUM(round(w_ace.mnt_br_atu,2)))*100,0) >= 0 THEN 0.01 ELSE -0.01 END AS ecart_br,
CASE WHEN round((SUM(mnt_remb_atu) - SUM(round(w_ace.mnt_remb_atu,2)))*100,0) >= 0 THEN 0.01 ELSE -0.01 END AS ecart_remb,
abs(round((SUM(mnt_br_atu) - SUM(round(w_ace.mnt_br_atu,2)))*100,0)) AS nb_ecart_br,
abs(round((SUM(mnt_remb_atu) - SUM(round(w_ace.mnt_remb_atu,2)))*100,0)) AS nb_ecart_remb
FROM w_ace
WHERE valo IN ('1','2','3') AND
(mnt_br_atu <> 0 OR mnt_remb_atu <> 0)
) subview ON valo IN ('1','2','3') AND
(mnt_br_atu <> 0 OR mnt_remb_atu <> 0)
ORDER BY rss_id
) subview
WHERE w_ace.rss_id = subview.rss_id AND
valo IN ('1','2','3') AND
(
mnt_br_atu IS DISTINCT FROM round(mnt_br_atu + ecart_br,2) OR
mnt_remb_atu IS DISTINCT FROM round(mnt_remb_atu + ecart_remb,2)
)
;
-- AJOUT DES PRESTATIONS MANQUANTES DANS CTI : ATU
-- On les repeche dans p_rsf_detail.non_valorise
EXECUTE FORMAT ('
INSERT INTO %I.p_rsf_detail (
base_remboursement,
base_remboursement_sauf_transition,
coefficient,
coefficient_geo,
coefficient_mco,
date_debut,
date_fin,
dmt,
finess,
mt,
no_rss,
nombre,
prestation_id,
prix_unitaire,
rss_id,
sejour_facture,
sejour_remboursable,
taux_remboursement)
SELECT
w_ace.mnt_br_atu as base_remboursement,
CASE
WHEN w_cti.date_sortie BETWEEN ''20130301'' AND ''20160229'' THEN (2 - 0.9965) * mnt_br_atu
WHEN w_cti.date_sortie BETWEEN ''20160301'' AND ''20170228'' THEN (2 - 0.9950) * mnt_br_atu
WHEN w_cti.date_sortie BETWEEN ''20170301'' AND ''20991231'' THEN (2 - 0.9930) * mnt_br_atu
ELSE mnt_br_atu END as base_remboursement_sauf_transition,
rsf.coefficient,
rsf.coefficient_geo,
rsf.coefficient_mco,
rsf.date_debut,
rsf.date_fin,
rsf.dmt,
rsf.finess,
rsf.mt,
rsf.no_rss,
rsf.nombre,
rsf.prestation_id,
CASE
WHEN w_cti.date_sortie BETWEEN ''20130301'' AND ''20160229'' THEN (2 - 0.9965) * mnt_br_atu
WHEN w_cti.date_sortie BETWEEN ''20160301'' AND ''20170228'' THEN (2 - 0.9950) * mnt_br_atu
WHEN w_cti.date_sortie BETWEEN ''20170301'' AND ''20991231'' THEN (2 - 0.9930) * mnt_br_atu
ELSE mnt_br_atu END as prix_unitaire,
rsf.rss_id,
w_ace.mnt_br_atu as sejour_facture,
w_ace.mnt_remb_atu as sejour_remboursable,
rsf.taux_remboursement
FROM
w_ace
JOIN w_cti ON w_ace.rss_id = w_cti.rss_id
JOIN %I.p_rsf_detail_non_valorise rsf ON rsf.rss_id = w_cti.rss_id
JOIN w_prestations t_prestations ON t_prestations.oid = rsf.prestation_id
WHERE 1=1
AND type_prestation_ace = ''ATU''
AND w_ace.valo IN (''1'',''2'',''3'')
AND w_ace.mnt_br_atu > 0
AND w_cti.cti_br_atu = 0
', i_schema, i_schema);
-- Report des montants sur RSF
EXECUTE FORMAT ('
UPDATE %I.p_rsf_detail
SET base_remboursement = round(w_ace.mnt_br_atu,2)
FROM w_ace, w_prestations t_prestations
WHERE w_ace.rss_id = p_rsf_detail.rss_id AND
prestation_id = t_prestations.oid AND
type_prestation_ace = ''ATU'' AND
round(w_ace.mnt_br_atu,2) <> base_remboursement
;
', i_schema)
;
EXECUTE FORMAT ('
UPDATE %I.p_rsf_detail
SET sejour_remboursable = round(w_ace.mnt_remb_atu,2)
FROM w_ace, w_prestations t_prestations
WHERE w_ace.rss_id = p_rsf_detail.rss_id AND
prestation_id = t_prestations.oid AND
type_prestation_ace = ''ATU'' AND
round(w_ace.mnt_remb_atu,2) <> sejour_remboursable
', i_schema)
;
---------------------
-- Traitement des SEh
---------------------
-- AJOUT DES PRESTATIONS MANQUANTES DANS CTI : SE
-- On les repeche dans p_rsf_detail.non_valorise
-- Traitement des arrondis
UPDATE w_ace SET
mnt_br_se = round(mnt_br_se + ecart_br,2),
mnt_remb_se = round(mnt_remb_se + ecart_remb,2)
FROM
(
SELECT w_ace.rss_id, row_number() OVER (ORDER BY rss_id),
CASE WHEN row_number() OVER (ORDER BY rss_id) <= nb_ecart_br THEN ecart_br ELSE 0 END AS ecart_br,
CASE WHEN row_number() OVER (ORDER BY rss_id) <= nb_ecart_remb THEN ecart_remb ELSE 0 END AS ecart_remb
FROM w_ace
JOIN
(
SELECT round((SUM(mnt_remb_se) - SUM(round(w_ace.mnt_remb_se,2))),2),
CASE WHEN round((SUM(mnt_br_se) - SUM(round(w_ace.mnt_br_se,2)))*100,0) >= 0 THEN 0.01 ELSE -0.01 END AS ecart_br,
CASE WHEN round((SUM(mnt_remb_se) - SUM(round(w_ace.mnt_remb_se,2)))*100,0) >= 0 THEN 0.01 ELSE -0.01 END AS ecart_remb,
abs(round((SUM(mnt_br_se) - SUM(round(w_ace.mnt_br_se,2)))*100,0)) AS nb_ecart_br,
abs(round((SUM(mnt_remb_se) - SUM(round(w_ace.mnt_remb_se,2)))*100,0)) AS nb_ecart_remb
FROM w_ace
WHERE valo IN ('1','2','3') AND
(mnt_br_se <> 0 OR mnt_remb_se <> 0)
) subview ON valo IN ('1','2','3') AND
(mnt_br_se <> 0 OR mnt_remb_se <> 0)
ORDER BY rss_id
) subview
WHERE w_ace.rss_id = subview.rss_id AND
valo IN ('1','2','3') AND
(
mnt_br_se IS DISTINCT FROM round(mnt_br_se + ecart_br,2) OR
mnt_remb_se IS DISTINCT FROM round(mnt_remb_se + ecart_remb,2)
)
;
EXECUTE FORMAT ('
INSERT INTO %I.p_rsf_detail (
base_remboursement,
base_remboursement_sauf_transition,
coefficient,
coefficient_geo,
coefficient_mco,
date_debut,
date_fin,
dmt,
finess,
mt,
no_rss,
nombre,
prestation_id,
prix_unitaire,
rss_id,
sejour_facture,
sejour_remboursable,
taux_remboursement)
SELECT
w_ace.mnt_br_se as base_remboursement,
CASE
WHEN w_cti.date_sortie BETWEEN ''20130301'' AND ''20160229'' THEN (2 - 0.9965) * mnt_br_se
WHEN w_cti.date_sortie BETWEEN ''20160301'' AND ''20170228'' THEN (2 - 0.9950) * mnt_br_se
WHEN w_cti.date_sortie BETWEEN ''20170301'' AND ''20991231'' THEN (2 - 0.9930) * mnt_br_se
ELSE mnt_br_se END as base_remboursement_sauf_transition,
rsf.coefficient,
rsf.coefficient_geo,
rsf.coefficient_mco,
rsf.date_debut,
rsf.date_fin,
rsf.dmt,
rsf.finess,
rsf.mt,
rsf.no_rss,
rsf.nombre,
rsf.prestation_id,
rsf.prix_unitaire,
rsf.rss_id,
w_ace.mnt_br_se as sejour_facture,
w_ace.mnt_br_se as sejour_remboursable,
rsf.taux_remboursement
FROM
w_ace
JOIN w_cti ON w_ace.rss_id = w_cti.rss_id
JOIN %I.p_rsf_detail_non_valorise rsf ON rsf.rss_id = w_cti.rss_id
JOIN w_prestations t_prestations ON t_prestations.oid = rsf.prestation_id
WHERE 1=1
AND type_prestation_ace = ''SE''
AND w_ace.valo IN (''1'', ''2'', ''3'')
AND w_ace.mnt_br_se > 0
AND w_cti.cti_br_se = 0
', i_schema, i_schema);
-- Suppression de lignes non valorisées si créées à tord (selon ecart cti/ace)
EXECUTE FORMAT ('
DROP TABLE IF EXISTS w_rsf_detail_non_valorise;
CREATE TEMP TABLE w_rsf_detail_non_valorise AS
SELECT w_cti.rss_id AS nv_rss_id,
p_rsf_detail.CTID AS nv_CTID,
p_rsf_detail.nombre AS nv_nombre,
p_rsf_detail.base_remboursement AS nv_base_remboursement,
p_rsf_detail.sejour_remboursable AS nv_sejour_remboursable,
t_prestations.code AS nv_prestation_code
FROM w_cti
JOIN w_ace ON w_cti.rss_id = w_ace.rss_id
JOIN %I.p_rsf_detail ON w_cti.rss_id = p_rsf_detail.rss_id AND est_ligne_rss IS DISTINCT FROM ''0''
JOIN w_prestations t_prestations On prestation_id = t_prestations.oid
WHERE mnt_br_se = 0 AND
valo IN (''1'',''2'',''3'') AND
p_rsf_detail.type = ''B'' AND
type_prestation_ace = ''SE'' AND
p_rsf_detail.base_remboursement > 0
;
', i_schema);
EXECUTE FORMAT ('
INSERT INTO %I.p_rsf_detail_non_valorise(
finess,
no_rss,
nature,
mt,
dmt,
date_debut,
date_fin,
nombre,
coefficient,
prix_unitaire,
base_remboursement,
taux_remboursement,
sejour_facture,
sejour_remboursable,
compteur,
ligne_t2a,
pec_fj,
coefficient_mco,
sejour_remboursable_2,
ghs_id,
sejour_rembourse_noemie,
nature_noemie,
prestation_id,
rss_id,
type,
coefficient_geo,
est_ligne_rss,
est_ligne_rum,
no_rum,
unite_medicale_id,
base_remboursement_rum,
montant_supplement_nf,
sejour_remboursable_rum,
pec_fj_id,
base_remboursement_sauf_transition,
base_remboursement_rum_sauf_transition,
regle,
regle_id,
coefficient_pacte_resp,
no_ligne
)
SELECT
finess,
no_rss,
nature,
mt,
dmt,
date_debut,
date_fin,
nombre,
coefficient,
prix_unitaire,
base_remboursement,
taux_remboursement,
sejour_facture,
sejour_remboursable,
compteur,
ligne_t2a,
pec_fj,
coefficient_mco,
sejour_remboursable_2,
ghs_id,
sejour_rembourse_noemie,
nature_noemie,
prestation_id,
rss_id,
type,
coefficient_geo,
est_ligne_rss,
est_ligne_rum,
no_rum,
unite_medicale_id,
base_remboursement_rum,
montant_supplement_nf,
sejour_remboursable_rum,
pec_fj_id,
base_remboursement_sauf_transition,
base_remboursement_rum_sauf_transition,
0::bigint AS regle,
0::bigint AS regle_id,
coefficient_pacte_resp,
no_ligne
FROM %I.p_rsf_detail
JOIN w_rsf_detail_non_valorise ON
rss_id = nv_rss_id AND
p_rsf_detail.CTID = nv_CTID
;
', i_schema, i_schema);
EXECUTE FORMAT ('
DELETE FROM %I.p_rsf_detail
USING w_rsf_detail_non_valorise
WHERE rss_id = nv_rss_id AND
p_rsf_detail.CTID = nv_CTID
', i_schema);
UPDATE w_cti SET
cti_nb_se = cti_nb_se - nv_nombre,
cti_br_se = cti_br_se - nv_base_remboursement,
cti_remb_se = cti_remb_se - nv_sejour_remboursable
FROM w_rsf_detail_non_valorise
WHERE rss_id = nv_rss_id
;
-- SE* correction des montant differents entre OVALIDE et ICTI
EXECUTE FORMAT ('
UPDATE %I.p_rsf_detail SET
base_remboursement = base_remboursement + ecart_br,
base_remboursement_sauf_transition = (base_remboursement + ecart_br) * coef_prud,
sejour_remboursable = sejour_remboursable + ecart_remb
FROM
(
SELECT 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(w_ace.mnt_br_se) - SUM(base_remboursement) AS ecart_br,
MAX(w_ace.mnt_remb_se) - SUM(sejour_remboursable) AS ecart_remb,
MAX(coef_prud) AS coef_prud
FROM %I.p_rsf_detail
JOIN w_prestations t_prestations ON prestation_id = t_prestations.oid
JOIN w_ace ON p_rsf_detail.rss_id = w_ace.rss_id
JOIN w_cti ON p_rsf_detail.rss_id = w_cti.rss_id
WHERE type_prestation_ace = ''SE'' AND
valo IN (''1'',''2'',''3'')
GROUP BY 1
HAVING
(
MAX(w_ace.mnt_br_se) <> SUM(base_remboursement) OR
MAX(w_ace.mnt_remb_se) <> SUM(sejour_remboursable)
) AND
abs(MAX(w_ace.mnt_br_se) - SUM(base_remboursement)) < 100
) subview
WHERE p_rsf_detail.rss_id = subview.rss_id AND
p_rsf_detail.CTID::text = subview.CTID_adjust
', i_schema, i_schema);
-- SE* Cas de deux lignes dont une coefficient 50
EXECUTE FORMAT ('
UPDATE %I.p_rsf_detail SET
base_remboursement = round(p_rsf_detail.base_remboursement * p_rsf_detail.prix_unitaire * p_rsf_detail.coefficient / tot_pu,2),
base_remboursement_sauf_transition = round(p_rsf_detail.base_remboursement_sauf_transition * p_rsf_detail.prix_unitaire * p_rsf_detail.coefficient / tot_pu,2),
sejour_remboursable = round(p_rsf_detail.sejour_remboursable * p_rsf_detail.prix_unitaire * p_rsf_detail.coefficient / tot_pu,2)
FROM
(
SELECT p_rsf_detail.rss_id,
base.cti_array_accum(prestation_id) AS prestation_id_array,
SUM(prix_unitaire*coefficient) AS tot_pu
FROM %I.p_rsf_detail
JOIN w_prestations t_prestations ON prestation_id = t_prestations.oid
JOIN %I.p_rss on rss_id = p_rss.oid
WHERE type_prestation_ace = ''SE''
GROUP BY 1
HAVING count(*) > 1 AND
count(DISTINCT p_rsf_detail.base_remboursement) = 1 AND
MIN(p_rsf_detail.coefficient) = 0.5 AND
SUM(prix_unitaire*coefficient) > 0
) subview
where p_rsf_detail.rss_id = subview.rss_id AND
p_rsf_detail.prestation_id = ANY(prestation_id_array)
', i_schema, i_schema, i_schema);
---------------------
-- Traitement des FTN FTR
---------------------
RAISE NOTICE '%', 'FTN';
-- AJOUT DES PRESTATIONS MANQUANTES DANS CTI : FTN FTR
-- On les repeche dans p_rsf_detail.non_valorise
-- Traitement des arrondis
UPDATE w_ace SET
mnt_br_ftn = round(mnt_br_ftn + ecart_br,2),
mnt_remb_ftn = round(mnt_remb_ftn + ecart_remb,2)
FROM
(
SELECT w_ace.rss_id, row_number() OVER (ORDER BY rss_id),
CASE WHEN row_number() OVER (ORDER BY rss_id) <= nb_ecart_br THEN ecart_br ELSE 0 END AS ecart_br,
CASE WHEN row_number() OVER (ORDER BY rss_id) <= nb_ecart_remb THEN ecart_remb ELSE 0 END AS ecart_remb
FROM w_ace
JOIN
(
SELECT round((SUM(mnt_remb_ftn) - SUM(round(w_ace.mnt_remb_ftn,2))),2),
CASE WHEN round((SUM(mnt_br_ftn) - SUM(round(w_ace.mnt_br_ftn,2)))*100,0) >= 0 THEN 0.01 ELSE -0.01 END AS ecart_br,
CASE WHEN round((SUM(mnt_remb_ftn) - SUM(round(w_ace.mnt_remb_ftn,2)))*100,0) >= 0 THEN 0.01 ELSE -0.01 END AS ecart_remb,
abs(round((SUM(mnt_br_ftn) - SUM(round(w_ace.mnt_br_ftn,2)))*100,0)) AS nb_ecart_br,
abs(round((SUM(mnt_remb_ftn) - SUM(round(w_ace.mnt_remb_ftn,2)))*100,0)) AS nb_ecart_remb
FROM w_ace
WHERE valo IN ('1','2','3') AND
(mnt_br_ftn <> 0 OR mnt_remb_ftn <> 0)
) subview ON valo IN ('1','2','3') AND
(mnt_br_ftn <> 0 OR mnt_remb_ftn <> 0)
ORDER BY rss_id
) subview
WHERE w_ace.rss_id = subview.rss_id AND
valo IN ('1','2','3') AND
(
mnt_br_ftn IS DISTINCT FROM round(mnt_br_ftn + ecart_br,2) OR
mnt_remb_ftn IS DISTINCT FROM round(mnt_remb_ftn + ecart_remb,2)
)
;
RAISE NOTICE '%', 'FTN. Transfert non valorise vers valorise' ;
EXECUTE FORMAT ('
INSERT INTO %I.p_rsf_detail (
base_remboursement,
base_remboursement_sauf_transition,
coefficient,
coefficient_geo,
coefficient_mco,
date_debut,
date_fin,
dmt,
finess,
mt,
no_rss,
nombre,
prestation_id,
prix_unitaire,
rss_id,
sejour_facture,
sejour_remboursable,
taux_remboursement)
SELECT
w_ace.mnt_br_ftn as base_remboursement,
CASE
WHEN w_cti.date_sortie BETWEEN ''20130301'' AND ''20160229'' THEN (2 - 0.9965) * mnt_br_ftn
WHEN w_cti.date_sortie BETWEEN ''20160301'' AND ''20170228'' THEN (2 - 0.9950) * mnt_br_ftn
WHEN w_cti.date_sortie BETWEEN ''20170301'' AND ''20991231'' THEN (2 - 0.9930) * mnt_br_ftn
ELSE mnt_br_ftn END as base_remboursement_sauf_transition,
rsf.coefficient,
rsf.coefficient_geo,
rsf.coefficient_mco,
rsf.date_debut,
rsf.date_fin,
rsf.dmt,
rsf.finess,
rsf.mt,
rsf.no_rss,
rsf.nombre,
rsf.prestation_id,
rsf.prix_unitaire,
rsf.rss_id,
w_ace.mnt_br_ftn as sejour_facture,
w_ace.mnt_br_ftn as sejour_remboursable,
rsf.taux_remboursement
FROM
w_ace
JOIN w_cti ON w_ace.rss_id = w_cti.rss_id
JOIN %I.p_rsf_detail_non_valorise rsf ON rsf.rss_id = w_cti.rss_id
JOIN w_prestations t_prestations ON t_prestations.oid = rsf.prestation_id
WHERE 1=1
AND type_prestation_ace = ''FTN''
AND w_ace.valo IN (''1'', ''2'', ''3'')
AND w_cti.cti_br_ftn = 0
AND w_ace.mnt_br_ftn > 0
', i_schema, i_schema);
-- Suppression de lignes non valorisées si créées à tord (selon ecart cti/ace)
EXECUTE FORMAT ('
DROP TABLE IF EXISTS w_rsf_detail_non_valorise;
CREATE TEMP TABLE w_rsf_detail_non_valorise AS
SELECT w_cti.rss_id AS nv_rss_id,
p_rsf_detail.CTID AS nv_CTID,
p_rsf_detail.nombre AS nv_nombre,
p_rsf_detail.base_remboursement AS nv_base_remboursement,
p_rsf_detail.sejour_remboursable AS nv_sejour_remboursable,
t_prestations.code AS nv_prestation_code
FROM w_cti
JOIN w_ace ON w_cti.rss_id = w_ace.rss_id
JOIN %I.p_rsf_detail ON w_cti.rss_id = p_rsf_detail.rss_id AND est_ligne_rss IS DISTINCT FROM ''0''
JOIN w_prestations t_prestations On prestation_id = t_prestations.oid
WHERE mnt_br_ftn = 0 AND
valo IN (''1'',''2'',''3'') AND
p_rsf_detail.type = ''B'' AND
type_prestation_ace = ''FTN''
;
', i_schema);
EXECUTE FORMAT ('
INSERT INTO %I.p_rsf_detail_non_valorise(
finess,
no_rss,
nature,
mt,
dmt,
date_debut,
date_fin,
nombre,
coefficient,
prix_unitaire,
base_remboursement,
taux_remboursement,
sejour_facture,
sejour_remboursable,
compteur,
ligne_t2a,
pec_fj,
coefficient_mco,
sejour_remboursable_2,
ghs_id,
sejour_rembourse_noemie,
nature_noemie,
prestation_id,
rss_id,
type,
coefficient_geo,
est_ligne_rss,
est_ligne_rum,
no_rum,
unite_medicale_id,
base_remboursement_rum,
montant_supplement_nf,
sejour_remboursable_rum,
pec_fj_id,
base_remboursement_sauf_transition,
base_remboursement_rum_sauf_transition,
regle,
regle_id,
coefficient_pacte_resp,
no_ligne
)
SELECT
finess,
no_rss,
nature,
mt,
dmt,
date_debut,
date_fin,
nombre,
coefficient,
prix_unitaire,
base_remboursement,
taux_remboursement,
sejour_facture,
sejour_remboursable,
compteur,
ligne_t2a,
pec_fj,
coefficient_mco,
sejour_remboursable_2,
ghs_id,
sejour_rembourse_noemie,
nature_noemie,
prestation_id,
rss_id,
type,
coefficient_geo,
est_ligne_rss,
est_ligne_rum,
no_rum,
unite_medicale_id,
base_remboursement_rum,
montant_supplement_nf,
sejour_remboursable_rum,
pec_fj_id,
base_remboursement_sauf_transition,
base_remboursement_rum_sauf_transition,
0::bigint AS regle,
0::bigint AS regle_id,
coefficient_pacte_resp,
no_ligne
FROM %I.p_rsf_detail
JOIN w_rsf_detail_non_valorise ON
rss_id = nv_rss_id AND
p_rsf_detail.CTID = nv_CTID
;
', i_schema, i_schema);
EXECUTE FORMAT ('
DELETE FROM %I.p_rsf_detail
USING w_rsf_detail_non_valorise
WHERE rss_id = nv_rss_id AND
p_rsf_detail.CTID = nv_CTID
', i_schema);
UPDATE w_cti SET
cti_nb_ftn = cti_nb_ftn - nv_nombre,
cti_br_ftn = cti_br_ftn - nv_base_remboursement,
cti_remb_ftn = cti_remb_ftn - nv_sejour_remboursable
FROM w_rsf_detail_non_valorise
WHERE rss_id = nv_rss_id
;
EXECUTE FORMAT ('
UPDATE %I.p_rsf_detail SET
base_remboursement = p_rsf_detail.base_remboursement + ecart_br_ftn,
base_remboursement_sauf_transition = p_rsf_detail.base_remboursement_sauf_transition + ecart_br_ftn,
sejour_remboursable = p_rsf_detail.sejour_remboursable + ecart_remb_ftn
FROM
(
SELECT p_rsf_detail.rss_id,
(MAX(ARRAY[to_char(p_rsf_detail.base_remboursement,''FM0000000''), p_rsf_detail.CTID::text]))[2]::tid AS CTID_update,
SUM(base_remboursement) AS base_remboursement,
SUM(sejour_remboursable) AS sejour_remboursable,
MAX(mnt_br_ftn) AS mnt_br_ftn,
MAX(mnt_remb_ftn) AS mnt_remb_ftn,
MAX(mnt_br_ftn) - SUM(base_remboursement) AS ecart_br_ftn,
MAX(mnt_remb_ftn) - SUM(sejour_remboursable) AS ecart_remb_ftn
FROM %I.p_rsf_detail
JOIN w_prestations t_prestations ON prestation_id = t_prestations.oid
JOIN w_ace ON p_rsf_detail.rss_id = w_ace.rss_id
WHERE type_prestation_ace = ''FTN''
GROUP BY 1
HAVING (MAX(mnt_br_ftn) - SUM(base_remboursement)) <> 0 OR
MAX(mnt_remb_ftn) - SUM(sejour_remboursable) <> 0
) subview
WHERE p_rsf_detail.rss_id = subview.rss_id AND
p_rsf_detail.CTID = subview.CTID_update
', i_schema, i_schema);
---------------------
-- Traitement des DM EXTERNE
---------------------
RAISE NOTICE '%', 'DM EXTERNE';
-- AJOUT DES PRESTATIONS MANQUANTES DANS CTI : DM EXTERNE
-- On les repeche dans p_rsf_detail.non_valorise
-- Traitement des arrondis
UPDATE w_ace SET
mnt_br_dm_ext = round(mnt_br_dm_ext + ecart_br,2),
mnt_remb_dm_ext = round(mnt_remb_dm_ext + ecart_remb,2)
FROM
(
SELECT w_ace.rss_id, row_number() OVER (ORDER BY rss_id),
CASE WHEN row_number() OVER (ORDER BY rss_id) <= nb_ecart_br THEN ecart_br ELSE 0 END AS ecart_br,
CASE WHEN row_number() OVER (ORDER BY rss_id) <= nb_ecart_remb THEN ecart_remb ELSE 0 END AS ecart_remb
FROM w_ace
JOIN
(
SELECT round((SUM(mnt_remb_dm_ext) - SUM(round(w_ace.mnt_remb_dm_ext,2))),2),
CASE WHEN round((SUM(mnt_br_dm_ext) - SUM(round(w_ace.mnt_br_dm_ext,2)))*100,0) >= 0 THEN 0.01 ELSE -0.01 END AS ecart_br,
CASE WHEN round((SUM(mnt_remb_dm_ext) - SUM(round(w_ace.mnt_remb_dm_ext,2)))*100,0) >= 0 THEN 0.01 ELSE -0.01 END AS ecart_remb,
abs(round((SUM(mnt_br_dm_ext) - SUM(round(w_ace.mnt_br_dm_ext,2)))*100,0)) AS nb_ecart_br,
abs(round((SUM(mnt_remb_dm_ext) - SUM(round(w_ace.mnt_remb_dm_ext,2)))*100,0)) AS nb_ecart_remb
FROM w_ace
WHERE valo IN ('1','2','3') AND
(mnt_br_dm_ext <> 0 OR mnt_remb_dm_ext <> 0)
) subview ON valo IN ('1','2','3') AND
(mnt_br_dm_ext <> 0 OR mnt_remb_dm_ext <> 0)
ORDER BY rss_id
) subview
WHERE w_ace.rss_id = subview.rss_id AND
valo IN ('1','2','3') AND
(
mnt_br_dm_ext IS DISTINCT FROM round(mnt_br_dm_ext + ecart_br,2) OR
mnt_remb_dm_ext IS DISTINCT FROM round(mnt_remb_dm_ext + ecart_remb,2)
)
;
RAISE NOTICE '%', 'DM EXT. Transfert non valorise vers valorise' ;
EXECUTE FORMAT ('
INSERT INTO %I.p_rsf_detail (
base_remboursement,
base_remboursement_sauf_transition,
coefficient,
coefficient_geo,
coefficient_mco,
date_debut,
date_fin,
dmt,
finess,
mt,
no_rss,
nombre,
prestation_id,
prix_unitaire,
rss_id,
sejour_facture,
sejour_remboursable,
taux_remboursement)
SELECT
w_ace.mnt_br_dm_ext as base_remboursement,
CASE
WHEN w_cti.date_sortie BETWEEN ''20130301'' AND ''20160229'' THEN (2 - 0.9965) * mnt_br_dm_ext
WHEN w_cti.date_sortie BETWEEN ''20160301'' AND ''20170228'' THEN (2 - 0.9950) * mnt_br_dm_ext
WHEN w_cti.date_sortie BETWEEN ''20170301'' AND ''20991231'' THEN (2 - 0.9930) * mnt_br_dm_ext
ELSE mnt_br_dm_ext END as base_remboursement_sauf_transition,
rsf.coefficient,
rsf.coefficient_geo,
rsf.coefficient_mco,
rsf.date_debut,
rsf.date_fin,
rsf.dmt,
rsf.finess,
rsf.mt,
rsf.no_rss,
rsf.nombre,
rsf.prestation_id,
rsf.prix_unitaire,
rsf.rss_id,
w_ace.mnt_br_dm_ext as sejour_facture,
w_ace.mnt_br_dm_ext as sejour_remboursable,
rsf.taux_remboursement
FROM
w_ace
JOIN w_cti ON w_ace.rss_id = w_cti.rss_id
JOIN %I.p_rsf_detail_non_valorise rsf ON rsf.rss_id = w_cti.rss_id
JOIN w_prestations t_prestations ON t_prestations.oid = rsf.prestation_id
WHERE 1=1
AND type_prestation_ace = ''DMI''
AND w_ace.valo IN (''1'', ''2'', ''3'')
AND w_cti.cti_br_dm_ext = 0
AND w_ace.mnt_br_dm_ext > 0
', i_schema, i_schema);
-- Suppression de lignes non valorisées si créées à tord (selon ecart cti/ace)
EXECUTE FORMAT ('
DROP TABLE IF EXISTS w_rsf_detail_non_valorise;
CREATE TEMP TABLE w_rsf_detail_non_valorise AS
SELECT w_cti.rss_id AS nv_rss_id,
p_rsf_detail.CTID AS nv_CTID,
p_rsf_detail.nombre AS nv_nombre,
p_rsf_detail.base_remboursement AS nv_base_remboursement,
p_rsf_detail.sejour_remboursable AS nv_sejour_remboursable,
t_prestations.code AS nv_prestation_code
FROM w_cti
JOIN w_ace ON w_cti.rss_id = w_ace.rss_id
JOIN %I.p_rsf_detail ON w_cti.rss_id = p_rsf_detail.rss_id AND est_ligne_rss IS DISTINCT FROM ''0''
JOIN w_prestations t_prestations On prestation_id = t_prestations.oid
WHERE mnt_br_dm_ext = 0 AND
valo IN (''1'',''2'',''3'') AND
p_rsf_detail.type = ''B'' AND
type_prestation_ace = ''DMI''
;
', i_schema);
EXECUTE FORMAT ('
INSERT INTO %I.p_rsf_detail_non_valorise(
finess,
no_rss,
nature,
mt,
dmt,
date_debut,
date_fin,
nombre,
coefficient,
prix_unitaire,
base_remboursement,
taux_remboursement,
sejour_facture,
sejour_remboursable,
compteur,
ligne_t2a,
pec_fj,
coefficient_mco,
sejour_remboursable_2,
ghs_id,
sejour_rembourse_noemie,
nature_noemie,
prestation_id,
rss_id,
type,
coefficient_geo,
est_ligne_rss,
est_ligne_rum,
no_rum,
unite_medicale_id,
base_remboursement_rum,
montant_supplement_nf,
sejour_remboursable_rum,
pec_fj_id,
base_remboursement_sauf_transition,
base_remboursement_rum_sauf_transition,
regle,
regle_id,
coefficient_pacte_resp,
no_ligne
)
SELECT
finess,
no_rss,
nature,
mt,
dmt,
date_debut,
date_fin,
nombre,
coefficient,
prix_unitaire,
base_remboursement,
taux_remboursement,
sejour_facture,
sejour_remboursable,
compteur,
ligne_t2a,
pec_fj,
coefficient_mco,
sejour_remboursable_2,
ghs_id,
sejour_rembourse_noemie,
nature_noemie,
prestation_id,
rss_id,
type,
coefficient_geo,
est_ligne_rss,
est_ligne_rum,
no_rum,
unite_medicale_id,
base_remboursement_rum,
montant_supplement_nf,
sejour_remboursable_rum,
pec_fj_id,
base_remboursement_sauf_transition,
base_remboursement_rum_sauf_transition,
0::bigint AS regle,
0::bigint AS regle_id,
coefficient_pacte_resp,
no_ligne
FROM %I.p_rsf_detail
JOIN w_rsf_detail_non_valorise ON
rss_id = nv_rss_id AND
p_rsf_detail.CTID = nv_CTID
;
', i_schema, i_schema);
EXECUTE FORMAT ('
DELETE FROM %I.p_rsf_detail
USING w_rsf_detail_non_valorise
WHERE rss_id = nv_rss_id AND
p_rsf_detail.CTID = nv_CTID
', i_schema);
UPDATE w_cti SET
cti_nb_dm_ext = cti_nb_dm_ext - nv_nombre,
cti_br_dm_ext = cti_br_dm_ext - nv_base_remboursement,
cti_remb_dm_ext = cti_remb_dm_ext - nv_sejour_remboursable
FROM w_rsf_detail_non_valorise
WHERE rss_id = nv_rss_id
;
EXECUTE FORMAT ('
UPDATE %I.p_rsf_detail SET
base_remboursement = p_rsf_detail.base_remboursement + ecart_br_dm_ext,
base_remboursement_sauf_transition = p_rsf_detail.base_remboursement_sauf_transition + ecart_br_dm_ext,
sejour_remboursable = p_rsf_detail.sejour_remboursable + ecart_remb_dm_ext
FROM
(
SELECT p_rsf_detail.rss_id,
(MAX(ARRAY[to_char(p_rsf_detail.base_remboursement,''FM0000000''), p_rsf_detail.CTID::text]))[2]::tid AS CTID_update,
SUM(base_remboursement) AS base_remboursement,
SUM(sejour_remboursable) AS sejour_remboursable,
MAX(mnt_br_dm_ext) AS mnt_br_dm_ext,
MAX(mnt_remb_dm_ext) AS mnt_remb_dm_ext,
MAX(mnt_br_dm_ext) - SUM(base_remboursement) AS ecart_br_dm_ext,
MAX(mnt_remb_dm_ext) - SUM(sejour_remboursable) AS ecart_remb_dm_ext
FROM %I.p_rsf_detail
JOIN w_prestations t_prestations ON prestation_id = t_prestations.oid
JOIN w_ace ON p_rsf_detail.rss_id = w_ace.rss_id
WHERE type_prestation_ace = ''DMI''
GROUP BY 1
HAVING (MAX(mnt_br_dm_ext) - SUM(base_remboursement)) <> 0 OR
MAX(mnt_remb_dm_ext) - SUM(sejour_remboursable) <> 0
) subview
WHERE p_rsf_detail.rss_id = subview.rss_id AND
p_rsf_detail.CTID = subview.CTID_update
', i_schema, i_schema);
---------------------
-- Traitement des MOP
---------------------
-- prestation spéciale pour les MOP qui ne sont pas passés par RSF
INSERT INTO pmsi.t_prestations (code, texte, texte_court)
SELECT 'MOPHNG', texte || ' (hors NGAP)', texte_court || ' (hors NGAP)'
FROM pmsi.t_prestations
WHERE code = 'MOP' AND
'MOPHNG' NOT IN (SELECT code FROM pmsi.t_prestations WHERE code IS NOT NULL)
;
-- Arrondis
UPDATE w_ace SET
mnt_br_mop = round(mnt_br_mop + ecart_br,2),
mnt_remb_mop = round(mnt_remb_mop + ecart_remb,2)
FROM
(
SELECT w_ace.rss_id, row_number() OVER (ORDER BY rss_id),
CASE WHEN row_number() OVER (ORDER BY rss_id) <= nb_ecart_br THEN ecart_br ELSE 0 END AS ecart_br,
CASE WHEN row_number() OVER (ORDER BY rss_id) <= nb_ecart_remb THEN ecart_remb ELSE 0 END AS ecart_remb
FROM w_ace
JOIN
(
SELECT round((SUM(mnt_remb_mop) - SUM(round(w_ace.mnt_remb_mop,2))),2),
CASE WHEN round((SUM(mnt_br_mop) - SUM(round(w_ace.mnt_br_mop,2)))*100,0) >= 0 THEN 0.01 ELSE -0.01 END AS ecart_br,
CASE WHEN round((SUM(mnt_remb_mop) - SUM(round(w_ace.mnt_remb_mop,2)))*100,0) >= 0 THEN 0.01 ELSE -0.01 END AS ecart_remb,
abs(round((SUM(mnt_br_mop) - SUM(round(w_ace.mnt_br_mop,2)))*100,0)) AS nb_ecart_br,
abs(round((SUM(mnt_remb_mop) - SUM(round(w_ace.mnt_remb_mop,2)))*100,0)) AS nb_ecart_remb
FROM w_ace
WHERE valo IN ('1','2','3') AND
(mnt_br_mop <> 0 OR mnt_remb_mop <> 0)
) subview ON valo IN ('1','2','3') AND
(mnt_br_mop <> 0 OR mnt_remb_mop <> 0)
ORDER BY rss_id
) subview
WHERE w_ace.rss_id = subview.rss_id AND
valo IN ('1','2','3') AND
(
mnt_br_mop IS DISTINCT FROM round(mnt_br_mop + ecart_br,2) OR
mnt_remb_mop IS DISTINCT FROM round(mnt_remb_mop + ecart_remb,2)
)
;
EXECUTE FORMAT ('
DELETE FROM %I.p_rsf_detail
USING
w_cti
,w_ace
,w_prestations t_prestations
WHERE 1=1
AND p_rsf_detail.prestation_id = t_prestations.oid
AND p_rsf_detail.rss_id = w_cti.rss_id
AND w_cti.rss_id = w_ace.rss_id
AND type_prestation_ace = ''MOPHNG''
', i_schema);
-- AJOUT DES PRESTATIONS MANQUANTES DANS CTI : MOP majoration personnes âgées
EXECUTE FORMAT ('
INSERT INTO %I.p_rsf_detail (
finess,
no_rss,
coefficient_geo,
coefficient_mco,
date_debut,
date_fin,
prix_unitaire,
base_remboursement,
taux_remboursement,
sejour_facture,
sejour_remboursable,
nombre,
prestation_id,
rss_id,
base_remboursement_sauf_transition,
no_ligne,
type,
fides_detail)
(SELECT
w_cti.finess,
w_cti.no_rss,
1,
1,
w_cti.date_sortie AS date_debut,
w_cti.date_sortie AS date_fin,
5::numeric as prix_unitaire,
w_ace.mnt_br_mop as base_remboursement,
round(base.cti_division(w_ace.mnt_remb_mop,w_ace.mnt_br_mop)*100,0) AS taux_remboursement,
w_ace.mnt_br_mop as sejour_facture,
w_ace.mnt_remb_mop as sejour_remboursable,
w_ace.mnt_br_mop/5 AS nombre,
t_prestations.oid AS prestation_id,
w_cti.rss_id,
w_ace.mnt_remb_mop as base_remboursement_sauf_transition,
w_cti.no_ligne,
''B''::text AS type,
0::integer AS fides_detail
FROM
w_ace
JOIN w_cti ON w_ace.rss_id = w_cti.rss_id
JOIN pmsi.t_prestations ON t_prestations.code = ''MOPHNG''
WHERE 1=1
AND w_ace.valo IN (''1'',''2'',''3'')
AND w_ace.mnt_br_mop > 0
)
', i_schema);
---------------------
-- Traitement des AP2
---------------------
-- Arrondis
UPDATE w_ace SET
mnt_br_med_ext = round(mnt_br_med_ext + ecart_br,2),
mnt_remb_med_ext = round(mnt_remb_med_ext + ecart_remb,2)
FROM
(
SELECT w_ace.rss_id, row_number() OVER (ORDER BY rss_id),
CASE WHEN row_number() OVER (ORDER BY rss_id) <= nb_ecart_br THEN ecart_br ELSE 0 END AS ecart_br,
CASE WHEN row_number() OVER (ORDER BY rss_id) <= nb_ecart_remb THEN ecart_remb ELSE 0 END AS ecart_remb
FROM w_ace
JOIN
(
SELECT round((SUM(mnt_remb_med_ext) - SUM(round(w_ace.mnt_remb_med_ext,2))),2),
CASE WHEN round((SUM(mnt_br_med_ext) - SUM(round(w_ace.mnt_br_med_ext,2)))*100,0) >= 0 THEN 0.01 ELSE -0.01 END AS ecart_br,
CASE WHEN round((SUM(mnt_remb_med_ext) - SUM(round(w_ace.mnt_remb_med_ext,2)))*100,0) >= 0 THEN 0.01 ELSE -0.01 END AS ecart_remb,
abs(round((SUM(mnt_br_med_ext) - SUM(round(w_ace.mnt_br_med_ext,2)))*100,0)) AS nb_ecart_br,
abs(round((SUM(mnt_remb_med_ext) - SUM(round(w_ace.mnt_remb_med_ext,2)))*100,0)) AS nb_ecart_remb
FROM w_ace
WHERE valo IN ('1','2','3') AND
(mnt_br_med_ext <> 0 OR mnt_remb_med_ext <> 0)
) subview ON valo IN ('1','2','3') AND
(mnt_br_med_ext <> 0 OR mnt_remb_med_ext <> 0)
ORDER BY rss_id
) subview
WHERE w_ace.rss_id = subview.rss_id AND
valo IN ('1','2','3') AND
(
mnt_br_med_ext IS DISTINCT FROM round(mnt_br_med_ext + ecart_br,2) OR
mnt_remb_med_ext IS DISTINCT FROM round(mnt_remb_med_ext + ecart_remb,2)
)
;
-- AP2 correction des montant differents entre OVALIDE et ICTI
EXECUTE FORMAT ('
UPDATE %I.p_rsf_detail SET
base_remboursement = w_ace.mnt_br_med_ext,
base_remboursement_sauf_transition = w_ace.mnt_br_med_ext,
prix_unitaire = w_ace.mnt_br_med_ext,
sejour_facture = w_ace.mnt_remb_med_ext,
sejour_remboursable = w_ace.mnt_remb_med_ext
FROM
w_cti
,w_ace
,w_prestations t_prestations
WHERE 1=1
AND p_rsf_detail.prestation_id = t_prestations.oid AND type_prestation_ace = ''AP2''
AND p_rsf_detail.rss_id = w_cti.rss_id
AND w_cti.rss_id = w_ace.rss_id
AND w_cti.cti_br_med <> w_ace.mnt_br_med_ext
AND w_cti.cti_remb_med <> w_ace.mnt_remb_med_ext;
', i_schema);
------------------
-- Traitement CCAM
------------------
-- Arrondis + ecarts d'un centime par dossier
UPDATE w_ace SET
mnt_br_ccam = round(mnt_br_ccam + ecart_br,2),
mnt_remb_ccam = round(mnt_remb_ccam + ecart_remb,2)
FROM
(
SELECT w_ace.rss_id, row_number() OVER (ORDER BY rss_id),
CASE WHEN row_number() OVER (ORDER BY rss_id) <= nb_ecart_br THEN ecart_br ELSE 0 END AS ecart_br,
CASE WHEN row_number() OVER (ORDER BY rss_id) <= nb_ecart_remb THEN ecart_remb ELSE 0 END AS ecart_remb
FROM w_ace
JOIN
(
SELECT round((SUM(mnt_remb_ccam) - SUM(round(w_ace.mnt_remb_ccam,2))),2),
CASE WHEN round((SUM(mnt_br_ccam) - SUM(round(w_ace.mnt_br_ccam,2)))*100,0) >= 0 THEN 0.01 ELSE -0.01 END AS ecart_br,
CASE WHEN round((SUM(mnt_remb_ccam) - SUM(round(w_ace.mnt_remb_ccam,2)))*100,0) >= 0 THEN 0.01 ELSE -0.01 END AS ecart_remb,
abs(round((SUM(mnt_br_ccam) - SUM(round(w_ace.mnt_br_ccam,2)))*100,0)) AS nb_ecart_br,
abs(round((SUM(mnt_remb_ccam) - SUM(round(w_ace.mnt_remb_ccam,2)))*100,0)) AS nb_ecart_remb
FROM w_ace
WHERE valo IN ('1','2','3') AND
(mnt_br_ccam <> 0 OR mnt_remb_ccam <> 0) AND
(round(mnt_br_ccam,2) <> mnt_br_ccam OR round(mnt_remb_ccam,2) <> mnt_remb_ccam)
) subview ON valo IN ('1','2','3') AND
(mnt_br_ccam <> 0 OR mnt_remb_ccam <> 0) AND
(round(mnt_br_ccam,2) <> mnt_br_ccam OR round(mnt_remb_ccam,2) <> mnt_remb_ccam)
ORDER BY rss_id
) subview
WHERE w_ace.rss_id = subview.rss_id AND
valo IN ('1','2','3') AND
(
mnt_br_ccam IS DISTINCT FROM round(mnt_br_ccam + ecart_br,2) OR
mnt_remb_ccam IS DISTINCT FROM round(mnt_remb_ccam + ecart_remb,2)
)
;
-- Ventilation au prorata
EXECUTE FORMAT ('
UPDATE %I.p_rsf_detail SET
base_remboursement = base_remboursement + round(base.cti_division(ecart_br,total_br)*base_remboursement,2),
sejour_remboursable = sejour_remboursable + round(base.cti_division(ecart_remb,total_remb)*sejour_remboursable,2)
FROM
(
SELECT p_rsf_detail.rss_id,
MAX(w_ace.mnt_br_ccam) - SUM(base_remboursement) AS ecart_br,
MAX(w_ace.mnt_remb_ccam) - SUM(sejour_remboursable) AS ecart_remb,
SUM(base_remboursement) AS total_br,
SUM(sejour_remboursable) AS total_remb,
count(*),
base.cti_array_accum(DISTINCT prestation_id) AS prestation_id_array
FROM %I.p_rsf_detail
JOIN w_prestations t_prestations ON prestation_id = t_prestations.oid
JOIN w_ace ON p_rsf_detail.rss_id = w_ace.rss_id
JOIN w_cti ON p_rsf_detail.rss_id = w_cti.rss_id
WHERE p_rsf_detail.type = ''C'' AND
type_prestation_ace = ''CCAM'' AND
valo IN (''1'',''2'',''3'')
GROUP BY 1
HAVING
(
MAX(w_ace.mnt_br_ccam) <> SUM(base_remboursement) OR
MAX(w_ace.mnt_remb_ccam) <> SUM(sejour_remboursable)
) AND
abs(MAX(w_ace.mnt_br_ccam) - SUM(base_remboursement)) < 5
) subview
WHERE p_rsf_detail.rss_id = subview.rss_id AND
p_rsf_detail.prestation_id = ANY(prestation_id_array)
', i_schema, i_schema);
-- puis Mise à jour de l'acte le plus gros dossier par dossier pour le centime restant
EXECUTE FORMAT ('
UPDATE %I.p_rsf_detail SET
base_remboursement = base_remboursement + ecart_br,
sejour_remboursable = sejour_remboursable + ecart_remb
FROM
(
SELECT p_rsf_detail.rss_id,
(MAX(ARRAY[to_char(base_remboursement-prix_unitaire*nombre*coefficient,''FM000000000000000.00''),p_rsf_detail.CTID::text]))[2]::text AS CTID_adjust,
MAX(w_ace.mnt_br_ccam) - SUM(base_remboursement) AS ecart_br,
MAX(w_ace.mnt_remb_ccam) - SUM(sejour_remboursable) AS ecart_remb
FROM %I.p_rsf_detail
JOIN w_prestations t_prestations ON prestation_id = t_prestations.oid
JOIN w_ace ON p_rsf_detail.rss_id = w_ace.rss_id
JOIN w_cti ON p_rsf_detail.rss_id = w_cti.rss_id
WHERE p_rsf_detail.type = ''C'' AND
type_prestation_ace = ''CCAM'' AND
valo IN (''1'',''2'',''3'')
GROUP BY 1
HAVING
(
MAX(w_ace.mnt_br_ccam) <> SUM(base_remboursement) OR
MAX(w_ace.mnt_remb_ccam) <> SUM(sejour_remboursable)
) AND
abs(MAX(w_ace.mnt_br_ccam) - SUM(base_remboursement)) < 5
) subview
WHERE p_rsf_detail.rss_id = subview.rss_id AND
p_rsf_detail.CTID::text = subview.CTID_adjust
', i_schema, i_schema);
------------------------------
-- Traitement des forfaits PAT
------------------------------
-- Suppression des PAT sur les mauvais dossiers
EXECUTE FORMAT ('
DELETE FROM %I.p_rsf_detail
USING
w_cti
,w_ace
,w_prestations t_prestations
WHERE 1=1
AND p_rsf_detail.prestation_id = t_prestations.oid
AND p_rsf_detail.rss_id = w_cti.rss_id
AND w_cti.rss_id = w_ace.rss_id
AND type_prestation_ace = ''PAT''
', i_schema);
-- Ajout des PAT manquants
EXECUTE FORMAT ('
INSERT INTO %I.p_rsf_detail (
base_remboursement,
base_remboursement_sauf_transition,
coefficient,
coefficient_geo,
coefficient_mco,
date_debut,
date_fin,
no_rss,
nombre,
prestation_id,
prix_unitaire,
rss_id,
sejour_facture,
sejour_remboursable,
taux_remboursement)
WITH w_deja_pat AS (
SELECT
p_rsf_detail.rss_id
FROM
%I.p_rsf_detail
JOIN w_prestations t_prestations ON t_prestations.oid = p_rsf_detail.prestation_id
WHERE
type_prestation_ace = ''PAT''
) SELECT
0 - CASE WHEN w_cti.date_sortie >= ''20190101''::date THEN 24 ELSE 18 END as base_remboursement,
0 - CASE WHEN w_cti.date_sortie >= ''20190101''::date THEN 24 ELSE 18 END as base_remboursement_sauf_transition,
1 as coefficient,
1 as coefficient_geo,
1 as coefficient_mco,
w_cti.date_sortie as date_debut,
w_cti.date_sortie as date_fin,
w_cti.no_rss,
-1 as nombre,
t_prestations.oid as prestaion_id,
CASE WHEN w_cti.date_sortie >= ''20190101''::date THEN 24 ELSE 18 END as prix_unitaire,
w_cti.rss_id,
0 - CASE WHEN w_cti.date_sortie >= ''20190101''::date THEN 24 ELSE 18 END as sejour_facture,
0 - CASE WHEN w_cti.date_sortie >= ''20190101''::date THEN 24 ELSE 18 END as sejour_remboursable,
100 as taux_remboursement
FROM
w_cti
JOIN w_ace ON w_ace.rss_id = w_cti.rss_id
LEFT JOIN w_deja_pat ON w_deja_pat.rss_id = w_cti.rss_id
,w_prestations t_prestations
WHERE 1=1
AND type_prestation_ace = ''PAT''
AND (w_ace.pf18 = ''1'' OR w_ace.tmf = ''1'')
AND w_deja_pat.rss_id IS NULL
', i_schema, i_schema);
EXECUTE FORMAT ('
UPDATE w_cti SET
cti_br_ngap = cti_br_ngap + subview.base_remboursement,
cti_remb_ngap = cti_remb_ngap + sejour_remboursable
FROM
(
SELECT p_rsf_detail.rss_id, sum(base_remboursement) AS base_remboursement, sum(sejour_remboursable) AS sejour_remboursable
FROM %I.p_rsf_detail
JOIN w_prestations t_prestations ON prestation_id = t_prestations.oid
JOIN w_ace ON p_rsf_detail.rss_id = w_ace.rss_id
WHERE type_prestation_ace = ''PAT'' AND
valo IN (''1'',''2'',''3'')
GROUP BY 1
) subview
WHERE w_cti.rss_id = subview.rss_id
', i_schema);
------------------
-- Traitement NGAP
------------------
UPDATE w_ace SET
mnt_br_ngap = round(mnt_br_ngap + ecart_br,2),
mnt_remb_ngap = round(mnt_remb_ngap + ecart_remb,2)
FROM
(
SELECT w_ace.rss_id, row_number() OVER (ORDER BY rss_id),
CASE WHEN row_number() OVER (ORDER BY rss_id) <= nb_ecart_br THEN ecart_br ELSE 0 END AS ecart_br,
CASE WHEN row_number() OVER (ORDER BY rss_id) <= nb_ecart_remb THEN ecart_remb ELSE 0 END AS ecart_remb
FROM w_ace
JOIN
(
SELECT round((SUM(mnt_remb_ngap) - SUM(round(w_ace.mnt_remb_ngap,2))),2),
CASE WHEN round((SUM(mnt_br_ngap) - SUM(round(w_ace.mnt_br_ngap,2)))*100,0) >= 0 THEN 0.01 ELSE -0.01 END AS ecart_br,
CASE WHEN round((SUM(mnt_remb_ngap) - SUM(round(w_ace.mnt_remb_ngap,2)))*100,0) >= 0 THEN 0.01 ELSE -0.01 END AS ecart_remb,
abs(round((SUM(mnt_br_ngap) - SUM(round(w_ace.mnt_br_ngap,2)))*100,0)) AS nb_ecart_br,
abs(round((SUM(mnt_remb_ngap) - SUM(round(w_ace.mnt_remb_ngap,2)))*100,0)) AS nb_ecart_remb
FROM w_ace
WHERE valo IN ('1','2','3') AND
(mnt_br_ngap <> 0 OR mnt_remb_ngap <> 0) AND
(round(mnt_br_ngap,2) <> mnt_br_ngap OR round(mnt_remb_ngap,2) <> mnt_remb_ngap)
) subview ON valo IN ('1','2','3') AND
(mnt_br_ngap <> 0 OR mnt_remb_ngap <> 0) AND
(round(mnt_br_ngap,2) <> mnt_br_ngap OR round(mnt_remb_ngap,2) <> mnt_remb_ngap)
ORDER BY rss_id
) subview
WHERE w_ace.rss_id = subview.rss_id AND
valo IN ('1','2','3') AND
(
mnt_br_ngap IS DISTINCT FROM round(mnt_br_ngap + ecart_br,2) OR
mnt_remb_ngap IS DISTINCT FROM round(mnt_remb_ngap + ecart_remb,2)
)
;
-- Suppression de lignes non valorisées si créées à tord (selon ecart cti/ace)
EXECUTE FORMAT ('
DROP TABLE IF EXISTS w_rsf_detail_non_valorise;
CREATE TEMP TABLE w_rsf_detail_non_valorise AS
SELECT w_cti.rss_id AS nv_rss_id,
p_rsf_detail.CTID AS nv_CTID,
p_rsf_detail.nombre AS nv_nombre,
p_rsf_detail.base_remboursement AS nv_base_remboursement,
p_rsf_detail.sejour_remboursable AS nv_sejour_remboursable,
t_prestations.code AS nv_prestation_code
FROM w_cti
JOIN w_ace ON w_cti.rss_id = w_ace.rss_id
JOIN %I.p_rsf_detail ON w_cti.rss_id = p_rsf_detail.rss_id AND est_ligne_rss IS DISTINCT FROM ''0''
JOIN w_prestations t_prestations On prestation_id = t_prestations.oid
WHERE mnt_br_ngap <> 0 AND
type_prestation_ace = ''NGAP'' AND
abs(round(cti_br_ngap,2) - round(mnt_br_ngap,2)) > 1 AND
valo IN (''1'',''2'',''3'') AND
p_rsf_detail.base_remboursement = abs(round(cti_br_ngap,2) - round(mnt_br_ngap,2))
;
', i_schema);
EXECUTE FORMAT ('
INSERT INTO %I.p_rsf_detail_non_valorise(
finess,
no_rss,
nature,
mt,
dmt,
date_debut,
date_fin,
nombre,
coefficient,
prix_unitaire,
base_remboursement,
taux_remboursement,
sejour_facture,
sejour_remboursable,
compteur,
ligne_t2a,
pec_fj,
coefficient_mco,
sejour_remboursable_2,
ghs_id,
sejour_rembourse_noemie,
nature_noemie,
prestation_id,
rss_id,
type,
coefficient_geo,
est_ligne_rss,
est_ligne_rum,
no_rum,
unite_medicale_id,
base_remboursement_rum,
montant_supplement_nf,
sejour_remboursable_rum,
pec_fj_id,
base_remboursement_sauf_transition,
base_remboursement_rum_sauf_transition,
regle,
regle_id,
coefficient_pacte_resp,
no_ligne
)
SELECT
finess,
no_rss,
nature,
mt,
dmt,
date_debut,
date_fin,
nombre,
coefficient,
prix_unitaire,
base_remboursement,
taux_remboursement,
sejour_facture,
sejour_remboursable,
compteur,
ligne_t2a,
pec_fj,
coefficient_mco,
sejour_remboursable_2,
ghs_id,
sejour_rembourse_noemie,
nature_noemie,
prestation_id,
rss_id,
type,
coefficient_geo,
est_ligne_rss,
est_ligne_rum,
no_rum,
unite_medicale_id,
base_remboursement_rum,
montant_supplement_nf,
sejour_remboursable_rum,
pec_fj_id,
base_remboursement_sauf_transition,
base_remboursement_rum_sauf_transition,
0::bigint AS regle,
0::bigint AS regle_id,
coefficient_pacte_resp,
no_ligne
FROM %I.p_rsf_detail
JOIN w_rsf_detail_non_valorise ON
rss_id = nv_rss_id AND
p_rsf_detail.CTID = nv_CTID
;
', i_schema, i_schema);
EXECUTE FORMAT ('
DELETE FROM %I.p_rsf_detail
USING w_rsf_detail_non_valorise
WHERE rss_id = nv_rss_id AND
p_rsf_detail.CTID = nv_CTID
;
', i_schema);
UPDATE w_cti SET
cti_nb_ngap = cti_nb_ngap - nv_nombre,
cti_br_ngap = cti_br_ngap - nv_base_remboursement,
cti_remb_ngap = cti_remb_ngap - nv_sejour_remboursable
FROM w_rsf_detail_non_valorise
WHERE rss_id = nv_rss_id
;
-- Ventilation au prorata
EXECUTE FORMAT ('
UPDATE %I.p_rsf_detail SET
base_remboursement = base_remboursement + round(base.cti_division(ecart_br,total_br)*base_remboursement,2),
sejour_remboursable = sejour_remboursable + round(base.cti_division(ecart_remb,total_remb)*sejour_remboursable,2)
FROM
(
SELECT p_rsf_detail.rss_id,
MAX(w_ace.mnt_br_ngap) - SUM(base_remboursement) AS ecart_br,
MAX(w_ace.mnt_remb_ngap) - SUM(sejour_remboursable) AS ecart_remb,
SUM(base_remboursement) AS total_br,
SUM(sejour_remboursable) AS total_remb,
count(*),
base.cti_array_accum(DISTINCT prestation_id) AS prestation_id_array
FROM %I.p_rsf_detail
JOIN w_prestations t_prestations ON prestation_id = t_prestations.oid
JOIN w_ace ON p_rsf_detail.rss_id = w_ace.rss_id
JOIN w_cti ON p_rsf_detail.rss_id = w_cti.rss_id
WHERE type_prestation_ace = ''NGAP'' AND
valo IN (''1'',''2'',''3'')
GROUP BY 1
HAVING
(
MAX(w_ace.mnt_br_ngap) <> SUM(base_remboursement) OR
MAX(w_ace.mnt_remb_ngap) <> SUM(sejour_remboursable)
) AND
abs(MAX(w_ace.mnt_br_ngap) - SUM(base_remboursement)) < 5
) subview
WHERE p_rsf_detail.rss_id = subview.rss_id AND
p_rsf_detail.prestation_id = ANY(prestation_id_array)
', i_schema, i_schema);
-- puis Mise à jour de l'acte le plus gros dossier par dossier pour le centime restant
EXECUTE FORMAT ('
UPDATE %I.p_rsf_detail SET
base_remboursement = base_remboursement + ecart_br,
sejour_remboursable = sejour_remboursable + ecart_remb
FROM
(
SELECT 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(w_ace.mnt_br_ngap) - SUM(base_remboursement) AS ecart_br,
MAX(w_ace.mnt_remb_ngap) - SUM(sejour_remboursable) AS ecart_remb
FROM %I.p_rsf_detail
JOIN w_prestations t_prestations ON prestation_id = t_prestations.oid
JOIN w_ace ON p_rsf_detail.rss_id = w_ace.rss_id
JOIN w_cti ON p_rsf_detail.rss_id = w_cti.rss_id
WHERE type_prestation_ace = ''NGAP'' AND
valo IN (''1'',''2'',''3'')
GROUP BY 1
HAVING
(
MAX(w_ace.mnt_br_ngap) <> SUM(base_remboursement) OR
MAX(w_ace.mnt_remb_ngap) <> SUM(sejour_remboursable)
) AND
abs(MAX(w_ace.mnt_br_ngap) - SUM(base_remboursement)) < 5
) subview
WHERE p_rsf_detail.rss_id = subview.rss_id AND
p_rsf_detail.CTID::text = subview.CTID_adjust
', i_schema, i_schema);
-------------------
-- Post traitements
-------------------
-- Alimentation fides dans rsf_detail selon rsf_total (sauf MOP)
EXECUTE FORMAT ('
UPDATE %I.p_rsf_detail
SET fides_detail = p_rsf_total.valorise_fides
FROM %I.p_rsf_total
WHERE p_rsf_total.rss_id = p_rsf_detail.rss_id AND
p_rsf_total.valorise_fides IS NOT NULL AND
fides_detail IS DISTINCT FROM p_rsf_total.valorise_fides AND
prestation_id <> ALL(SELECT t_prestations.oid FROM pmsi.t_prestations WHERE code IN (''MOPHNG'') );
', i_schema, i_schema);
EXECUTE FORMAT ('
UPDATE %I.p_rsf_detail
SET fides_detail = 0
WHERE fides_detail IS DISTINCT FROM ''0'' AND
prestation_id = ANY(SELECT t_prestations.oid FROM pmsi.t_prestations WHERE code IN (''MOPHNG'') );
', i_schema);
RETURN 'OK';
END;