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.
 
 

1694 lines
76 KiB

return: text
lang: plpgsql
parameters:
p0:
type: bigint
name: i_controle_id
default: "NULL"
p1:
type: text
name: i_use_cache
default: "0"
src: |
DECLARE
ref refcursor;
request text := '';
_use_cache text;
_controle_id bigint;
_controle_code text;
_controle_rule_id bigint;
_sqlcmd_where text;
_sqlcmd_justificatif text;
_sqlcmd_insert text;
_nb_rules numeric := 0;
_nb_rules_error numeric := 0;
_last_execution_ok text;
_EXPERT_DATE_DEBUT date;
_c int;
_d int;
_p int;
_f int;
_l int;
_x int;
_x_b int;
_y int;
_i int;
_e int;
_ctl_string text;
_ctl_field text;
_ctl_field_key text;
_ctl_fieldType text;
_ctl_fieldDelimiter text;
_ctl_rule_i int;
_ctl_rule_fields_array text[];
_ctl_rule_operators_array text[];
_ctl_rule_values_array text[];
_ctl_operator text;
_ctl_operator_2 text;
_ctl_operator_b text;
_ctl_values text;
_ctl_values_2 text;
_ctl_values_array text[];
_ctl_value text;
_ctl_list text;
_ctl_list_array text[];
_ctl_new_where text;
_ctl_new_where_un text;
_sqlcmd_new_where text;
_ctl_subview_field_key text;
_ctl_subview_operator text;
_ctl_subview_value text;
_subviews text[];
_subviews_key text[];
_subviews_jfield text[];
_subviews_count int;
BEGIN
-- Module activé ?
INSERT INTO pmsi.t_divers (code, texte, valeur, description)
SELECT
'EXPERT_ACTIVE',
'Module EXPERT activé',
'0',
'1=Activé'
WHERE 'EXPERT_ACTIVE' NOT IN (SELECT code FROM pmsi.t_divers);
INSERT INTO pmsi.t_divers (code, texte, valeur, description, valeur_date)
SELECT
'EXPERT_DATE_DEBUT',
'Date séjours à contrôler',
'20130101',
'Date de début des séjours à contrôler',
'20130101'
WHERE 'EXPERT_DATE_DEBUT' NOT IN (SELECT code FROM pmsi.t_divers);
IF NOT EXISTS (SELECT * FROM pmsi.t_divers WHERE code = 'EXPERT_ACTIVE' AND valeur = '1') THEN
return 'Module inactivé';
END IF;
-- règles ?
IF NOT EXISTS (SELECT * FROM pmsi.t_expert_controle_rule LIMIT 1) THEN
return 'Pas de règle';
END IF;
RAISE NOTICE '%','Extraction des RSS à traiter';
_EXPERT_DATE_DEBUT = (SELECT valeur_date FROM pmsi.t_divers WHERE code = 'EXPERT_DATE_DEBUT');
if _EXPERT_DATE_DEBUT IS NULL THEN
_EXPERT_DATE_DEBUT = '2013-01-01';
END IF;
-- Table de travail
-- Si pas d'utilisation du cache, recréer les tables
_use_cache = COALESCE(i_use_cache,'0');
IF _use_cache = '1' THEN
IF NOT EXISTS (SELECT * FROM pg_class WHERE relname = 'pmsi_expert_cache_rss') THEN
_use_cache = '0';
END IF;
END IF;
IF _use_cache IS DISTINCT FROM '1' THEN
DROP TABLE IF EXISTS w_rss;
CREATE TEMP TABLE w_rss AS
SELECT
v_rss_1.rss_id AS oid,
v_rss_1.finess,
finess_id,
finess_texte,
finess_section_id,
finess_section_code,
finess_section_texte,
CASE WHEN t_finess.type_etablissement = '1' THEN '1' ELSE '2' END AS type_etablissement,
CASE WHEN COALESCE(t_finess.datim_categorie,'') <> '' THEN t_finess.datim_categorie
WHEN t_finess.type_etablissement = '1' THEN '1'
WHEN t_finess.type_etablissement = '2' THEN '3'
WHEN t_finess.type_etablissement = '3' THEN '3'
ELSE '' END AS ets_datim_categorie,
COALESCE(t_finess.datim_autorisation_cardio,0) AS ets_datim_cardio,
COALESCE(t_finess.datim_autorisation_neuro,0) AS ets_datim_neuro,
COALESCE(t_finess.datim_autorisation_rea,0) AS ets_datim_rea,
COALESCE(t_finess.datim_autorisation_rep,0) AS ets_datim_rep,
COALESCE(t_finess.datim_autorisation_nn,0) AS ets_datim_nn,
COALESCE(t_finess.datim_service_urgence,0) AS ets_datim_urgence,
COALESCE(t_finess.datim_service_ssr,0) AS ets_datim_ssr,
COALESCE(t_finess.datim_service_sld,0) AS ets_datim_sld,
COALESCE(t_finess.datim_service_psy,0) AS ets_datim_psy,
patient_id,
no_patient,
v_rss_1.rss_id,
v_rss_1.no_rss,
v_rss_1.no_sejour_administratif,
traitement_epmsi,
traitement_epmsi_texte,
code_retour_groupage,
en_cours,
en_cours_etat,
en_cours_texte_tres_court,
date_part('year',v_rss_1.date_sortie) AS annee_sortie,
v_rss_1.mois_sortie,
v_rss_1.mois_sortie_texte,
v_rss_1.mois_sortie_mm_code,
v_rss_1.mois_sortie_mm_texte,
v_rss_1.date_entree,
v_rss_1.date_sortie,
unite_medicale_principale_id,
unite_medicale_principale_code,
unite_medicale_principale_texte,
rehosp_meme_ghm,
mode_entree,
mode_entree || provenance AS provenance,
mode_sortie,
mode_sortie || destination AS destination,
0::bigint AS sejour_precedent_rss_id,
NULL::date AS sejour_precedent_date_entree,
NULL::date AS sejour_precedent_date_sortie,
''::text AS sejour_precedent_ghm_code,
v_rss_1.sexe,
sexe_texte_court,
sexe_texte,
v_rss_1.date_naissance,
age,
code_postal,
code_postal_id,
ghm_id,
CASE WHEN ghm_id <> 0 THEN ghm_code ELSE '' END AS ghm_code,
ghm_texte,
ghm_section_id,
ghm_section_code,
ghm_section_texte,
ghm5_id,
ghm5_code,
'0'::text AS ghm5_datim_conf,
''::text AS ghm_datim_tghm,
0::smallint AS ghm_datim_cti_1orj,
mco,
mco_texte,
substr(ghm_code,3,1) AS ghm3,
severite_ghm_code AS severite,
CASE
WHEN severite_ghm_code IN ('1','A') THEN 1
WHEN severite_ghm_code IN ('2','B') THEN 2
WHEN severite_ghm_code IN ('3','C') THEN 3
WHEN severite_ghm_code IN ('4','D') THEN 4
ELSE 0
END AS ghm_cma,
severite_ghm_code,
severite_ghm_texte,
cmd_id,
cmd_code,
cmd_texte,
cas_id,
cas_code,
cas_texte,
ghm_id AS ghmrsa_id,
ghm_code AS ghmrsa_code,
ghm_id AS ghmrsa_in_id,
ghm_code AS ghmrsa_in_code,
ghs_id AS ghsrsa_id,
ghs_code AS ghsrsa_code,
ghs_id,
trim(ghs_code) as ghs_code,
ghs_texte,
ghs_borne_basse,
ghs_borne_haute,
dms_nationale_ghs,
ecart_dms_nationale_ghs,
dms_ghm_1,
ecart_dms_ghm_1,
dms_ghm_2,
ecart_dms_ghm_2,
dms_ghm_3,
ecart_dms_ghm_3,
dms_ghm_hospidiag,
ecart_dms_ghm_hospidiag,
nb_rum,
nb_exh,
nb_exh as nb_exh_rsa,
ca_exh,
nb_exb,
ca_exb,
ca_perte_exb,
nb_ghs,
ca_ghs,
ca_ghs_theorique,
forfait_facture,
specialite_medecin_rss_id,
specialite_medecin_rss_code,
specialite_medecin_rss_texte,
specialite_interne_medecin_rss_id,
specialite_interne_medecin_rss_code,
specialite_interne_medecin_rss_texte,
medecin_rss_id,
medecin_rss_code,
medecin_rss_nom,
specialite_medecin_reference_rss_id,
specialite_medecin_reference_rss_code,
specialite_medecin_reference_rss_texte,
specialite_interne_medecin_reference_rss_id,
specialite_interne_medecin_reference_rss_code,
specialite_interne_medecin_reference_rss_texte,
medecin_reference_rss_id,
medecin_reference_rss_code,
medecin_reference_rss_nom,
medecin_rss_section_id,
medecin_rss_section_code,
medecin_rss_section_texte,
comite_medical_id,
prestation_principale_id,
prestation_principale_code,
diagnostic_principal_id,
CASE WHEN diagnostic_principal_id <> 0 THEN diagnostic_principal_code ELSE '' END AS diagnostic_principal_code,
diagnostic_principal_texte,
0::numeric AS diagnostic_principal_datim_rare,
0::numeric AS diagnostic_principal_datim_dpchir,
0::numeric AS diagnostic_principal_datim_zinhab,
0::numeric AS diagnostic_principal_datim_imprecis,
0::numeric AS diagnostic_principal_datim_zaffchr,
0::numeric AS diagnostic_principal_datim_timprecis,
0::numeric AS diagnostic_principal_datim_tintox,
0::numeric AS diagnostic_principal_datim_cma,
0::numeric AS diagnostic_principal_datim_cti_cma_fils,
0::numeric AS diagnostic_principal_datim_cti_cma_frere,
0::numeric AS diagnostic_principal_datim_dpacte,
0::numeric AS diagnostic_principal_datim_dgcpt669,
0::numeric AS diagnostic_principal_datim_brulure,
0::numeric AS diagnostic_principal_datim_esth,
0::numeric AS diagnostic_principal_datim_affaig,
0::numeric AS diagnostic_principal_datim_pbsexe,
0::numeric AS diagnostic_principal_datim_sexed,
0::numeric AS diagnostic_principal_datim_pbage,
0::numeric AS diagnostic_principal_datim_cl1v,
0::numeric AS diagnostic_principal_datim_cl2v,
0::numeric AS diagnostic_principal_datim_cl3v,
0::numeric AS diagnostic_principal_datim_cl4v,
0::numeric AS diagnostic_principal_datim_cl5v,
0::numeric AS diagnostic_principal_datim_cl6v,
0::numeric AS diagnostic_principal_datim_compimprecis,
0::numeric AS diagnostic_principal_datim_seance,
diagnostic_relie_id,
CASE WHEN diagnostic_relie_id <> 0 THEN diagnostic_relie_code ELSE '' END AS diagnostic_relie_code,
diagnostic_relie_texte,
diagnostic_relie_section_id,
diagnostic_relie_section_code,
diagnostic_relie_section_texte,
0::numeric AS diagnostic_relie_datim_rare,
0::numeric AS diagnostic_relie_datim_dpchir,
0::numeric AS diagnostic_relie_datim_zinhab,
0::numeric AS diagnostic_relie_datim_imprecis,
0::numeric AS diagnostic_relie_datim_zaffchr,
0::numeric AS diagnostic_relie_datim_timprecis,
0::numeric AS diagnostic_relie_datim_tintox,
0::numeric AS diagnostic_relie_datim_cma,
0::numeric AS diagnostic_relie_datim_cti_cma_fils,
0::numeric AS diagnostic_relie_datim_cti_cma_frere,
0::numeric AS diagnostic_relie_datim_dpacte,
0::numeric AS diagnostic_relie_datim_dgcpt669,
0::numeric AS diagnostic_relie_datim_brulure,
0::numeric AS diagnostic_relie_datim_esth,
0::numeric AS diagnostic_relie_datim_affaig,
0::numeric AS diagnostic_relie_datim_pbsexe,
0::numeric AS diagnostic_relie_datim_sexed,
0::numeric AS diagnostic_relie_datim_pbage,
0::numeric AS diagnostic_relie_datim_cl1v,
0::numeric AS diagnostic_relie_datim_cl2v,
0::numeric AS diagnostic_relie_datim_cl3v,
0::numeric AS diagnostic_relie_datim_cl4v,
0::numeric AS diagnostic_relie_datim_cl5v,
0::numeric AS diagnostic_relie_datim_cl6v,
0::numeric AS diagnostic_relie_datim_compimprecis,
NULL::smallint[] AS pathologies_chroniques_non_codees,
''::text AS diagnostic_double_code,
''::text AS liste_diagnostics,
0::smallint AS diagnostic_associe_brulure,
NULL::bigint[] as da_array,
NULL::text[] as diagnostics_documentaires,
acte_principal_id,
acte_principal_code,
acte_principal_texte,
NULL::bigint[] as acte_id_array,
''::text as type_sejour,
0::bigint as age_jours,
duree_sejour,
nb_rsa,
nb_seances,
nb_rsa_0n,
nb_rsa_1n,
nb_rsa_2n,
nb_rsa_xn,
nb_factures_nulles,
v_rss_1.base_remboursement,
sejour_facture,
v_rss_1.taux_remboursement,
v_rsf_total_1.exoneration_tm_code,
v_rsf_total_1.exoneration_tm_texte,
sejour_remboursable,
honoraires_factures,
honoraires_remboursable,
t2a_facture,
dmi_facture,
phc_facture,
participation_assure_avant_oc,
sejour_remboursable_2,
honoraires_remboursable_2,
montant_dmi_ghs2006,
igs2,
no_oid,
mcos_code,
mcos_texte,
mcos_id,
rss_mere_id,
poids_bebe,
age_gestationnel,
date_dernieres_regles,
v_rss_1.confirmation_codage,
type_machine_rdth,
type_dosimetrie,
numero_innovation,
CASE WHEN p_vidhosp.rss_id IS NOT NULL THEN '1' ELSE '0' END AS vidhosp,
COALESCE(p_vidhosp.code_pec,'1') AS vidhosp_code_pec,
COALESCE(p_vidhosp.montant_tm,0) AS vidhosp_montant_tm,
COALESCE(p_vidhosp.hospit_nouveau_ne, '0'::text) as vidhosp_hospit_nouveau_ne,
v_rsf_total_1.valorise_fides_code,
p_rss_maternite.accouchement_hors_img as mat_accouchement_hors_img,
p_rss_maternite.age_gestationnel_manquant as mat_age_gestationnel_manquant,
p_rss_maternite.age_gestationnel_inf_22sa as mat_age_gestationnel_inf_22sa,
p_rss_maternite.avec_acte_accouchement as mat_avec_acte_accouchement,
p_rss_maternite.confirmation_codage as mat_confirmation_codage,
p_rss_maternite.ecart_age_gestationnel as mat_ecart_age_gestationnel,
p_rss_maternite.hors_cmd_14 as mat_hors_cmd_14,
p_rss_maternite.hors_etablissement as mat_hors_etablissement,
raac_id
FROM pmsi.v_rss_1
JOIN base.t_finess ON t_finess.code = v_rss_1.finess
JOIN pmsi.v_rsf_total_1 ON (v_rss_1.rss_id = v_rsf_total_1.rss_id)
LEFT JOIN pmsi.p_vidhosp ON v_rss_1.rss_id = p_vidhosp.rss_id
LEFT JOIN pmsi.p_rss_maternite ON v_rss_1.rss_id = p_rss_maternite.rss_id
WHERE v_rss_1.date_sortie >= _EXPERT_DATE_DEBUT
;
ALTER TABLE w_rss ADD CONSTRAINT w_rss_pk PRIMARY KEY (oid);
CREATE INDEX w_rss_i1 ON w_rss USING btree (oid);
CREATE INDEX w_rss_i2 ON w_rss USING btree (diagnostic_principal_code);
CREATE INDEX w_rss_i3 ON w_rss USING btree (diagnostic_relie_code);
CREATE INDEX w_rss_i4 ON w_rss USING btree (acte_principal_code);
CREATE INDEX w_rss_i5 ON w_rss USING btree (annee_sortie);
RAISE NOTICE '%','Association RSA';
UPDATE w_rss SET
type_sejour = p_rsa.type_sejour,
age_jours = p_rsa.age_jours
FROM
pmsi.p_rsa
WHERE
p_rsa.rss_id = w_rss.rss_id;
RAISE NOTICE '%','Association DATIM GHM';
UPDATE w_rss SET
ghm_datim_tghm = t_datim_ghminfo.tghm,
ghm_datim_cti_1orj = t_datim_ghminfo.cti_1orj
FROM pmsi.t_datim_ghminfo
WHERE t_datim_ghminfo.ghm_id = w_rss.ghm_id AND
date_sortie BETWEEN date_debut AND date_fin AND
type_etablissement = t_datim_ghminfo.typets AND
(
t_datim_ghminfo.tghm <> '' OR
t_datim_ghminfo.cti_1orj <> 0
)
;
RAISE NOTICE '%','Association DATIM RACINE';
UPDATE w_rss SET
ghm5_datim_conf = t_datim_racineinfo.conf::text
FROM pmsi.t_datim_racineinfo
WHERE t_datim_racineinfo.ghm5_id = w_rss.ghm5_id AND
w_rss.date_sortie BETWEEN t_datim_racineinfo.date_debut AND t_datim_racineinfo.date_fin AND
w_rss.type_etablissement = t_datim_racineinfo.typets AND
t_datim_racineinfo.conf = 1
;
RAISE NOTICE '%','Association DATIM DP';
UPDATE w_rss SET
diagnostic_principal_datim_rare = t_datim_diaginfo.rare,
diagnostic_principal_datim_dpchir = t_datim_diaginfo.dpchir,
diagnostic_principal_datim_zinhab = t_datim_diaginfo.zinhab,
diagnostic_principal_datim_imprecis = t_datim_diaginfo.imprecis,
diagnostic_principal_datim_zaffchr = t_datim_diaginfo.zaffchr,
diagnostic_principal_datim_timprecis = t_datim_diaginfo.timprecis,
diagnostic_principal_datim_tintox = t_datim_diaginfo.tintox,
diagnostic_principal_datim_cma = t_datim_diaginfo.cma,
diagnostic_principal_datim_cti_cma_fils = t_datim_diaginfo.cti_cma_fils,
diagnostic_principal_datim_cti_cma_frere = t_datim_diaginfo.cti_cma_frere,
diagnostic_principal_datim_dpacte = t_datim_diaginfo.dpacte,
diagnostic_principal_datim_dgcpt669 = t_datim_diaginfo.dgcpt669,
diagnostic_principal_datim_brulure = t_datim_diaginfo.brulure,
diagnostic_principal_datim_esth = t_datim_diaginfo.esth,
diagnostic_principal_datim_affaig = t_datim_diaginfo.affaig,
diagnostic_principal_datim_pbsexe = CASE
WHEN sexe <> 1 AND t_datim_diaginfo.sexed = 1 THEN 1
WHEN sexe <> 2 AND t_datim_diaginfo.sexed = 2 THEN 1
ELSE 0 END,
diagnostic_principal_datim_sexed = t_datim_diaginfo.sexed,
diagnostic_principal_datim_pbage = CASE
WHEN t_datim_diaginfo.cl1v > 0 AND date_sortie - date_naissance < 29 THEN 1
WHEN t_datim_diaginfo.cl2v > 0 AND date_sortie - date_naissance >= 29 AND age = 0 THEN 1
WHEN t_datim_diaginfo.cl3v > 0 AND age >= 1 AND age < 10 THEN 1
WHEN t_datim_diaginfo.cl4v > 0 AND age >= 10 AND age < 20 THEN 1
WHEN t_datim_diaginfo.cl5v > 0 AND age >= 20 AND age < 65 THEN 1
WHEN t_datim_diaginfo.cl6v > 0 AND age >= 65 THEN 1
ELSE 0 END,
diagnostic_principal_datim_cl1v = t_datim_diaginfo.cl1v,
diagnostic_principal_datim_cl2v = t_datim_diaginfo.cl2v,
diagnostic_principal_datim_cl3v = t_datim_diaginfo.cl3v,
diagnostic_principal_datim_cl4v = t_datim_diaginfo.cl4v,
diagnostic_principal_datim_cl5v = t_datim_diaginfo.cl5v,
diagnostic_principal_datim_cl6v = t_datim_diaginfo.cl6v,
diagnostic_principal_datim_compimprecis = t_datim_diaginfo.compimprecis,
diagnostic_principal_datim_seance = t_datim_diaginfo.seance
FROM pmsi.t_datim_diaginfo
WHERE diagnostic_principal_id = t_datim_diaginfo.diagnostic_id AND
date_sortie BETWEEN date_debut AND date_fin AND
(
t_datim_diaginfo.rare <> 0 OR
t_datim_diaginfo.dpchir <> 0 OR
t_datim_diaginfo.zinhab <> 0 OR
t_datim_diaginfo.imprecis <> 0 OR
t_datim_diaginfo.zaffchr <> 0 OR
t_datim_diaginfo.timprecis <> 0 OR
t_datim_diaginfo.tintox <> 0 OR
t_datim_diaginfo.cma <> 0 OR
t_datim_diaginfo.cti_cma_fils <> 0 OR
t_datim_diaginfo.cti_cma_frere <> 0 OR
t_datim_diaginfo.dpacte <> 0 OR
t_datim_diaginfo.dgcpt669 <> 0 OR
t_datim_diaginfo.brulure <> 0 OR
t_datim_diaginfo.esth <> 0 OR
t_datim_diaginfo.affaig <> 0 OR
t_datim_diaginfo.sexed <> 0 OR
t_datim_diaginfo.cl1v <> 0 OR
t_datim_diaginfo.cl2v <> 0 OR
t_datim_diaginfo.cl3v <> 0 OR
t_datim_diaginfo.cl4v <> 0 OR
t_datim_diaginfo.cl5v <> 0 OR
t_datim_diaginfo.cl6v <> 0 OR
t_datim_diaginfo.compimprecis <> 0 OR
t_datim_diaginfo.seance <> 0
)
;
RAISE NOTICE '%','Association DATIM DR';
UPDATE w_rss SET
diagnostic_relie_datim_rare = t_datim_diaginfo.rare,
diagnostic_relie_datim_dpchir = t_datim_diaginfo.dpchir,
diagnostic_relie_datim_zinhab = t_datim_diaginfo.zinhab,
diagnostic_relie_datim_imprecis = t_datim_diaginfo.imprecis,
diagnostic_relie_datim_zaffchr = t_datim_diaginfo.zaffchr,
diagnostic_relie_datim_timprecis = t_datim_diaginfo.timprecis,
diagnostic_relie_datim_tintox = t_datim_diaginfo.tintox,
diagnostic_relie_datim_cma = t_datim_diaginfo.cma,
diagnostic_relie_datim_cti_cma_fils = t_datim_diaginfo.cti_cma_fils,
diagnostic_relie_datim_cti_cma_frere = t_datim_diaginfo.cti_cma_frere,
diagnostic_relie_datim_dpacte = t_datim_diaginfo.dpacte,
diagnostic_relie_datim_dgcpt669 = t_datim_diaginfo.dgcpt669,
diagnostic_relie_datim_brulure = t_datim_diaginfo.brulure,
diagnostic_relie_datim_esth = t_datim_diaginfo.esth,
diagnostic_relie_datim_affaig = t_datim_diaginfo.affaig,
diagnostic_relie_datim_pbsexe = CASE
WHEN sexe <> 1 AND t_datim_diaginfo.sexed = 1 THEN 1
WHEN sexe <> 2 AND t_datim_diaginfo.sexed = 2 THEN 1
ELSE 0 END,
diagnostic_relie_datim_sexed = t_datim_diaginfo.sexed,
diagnostic_relie_datim_pbage = CASE
WHEN t_datim_diaginfo.cl1v > 0 AND date_sortie - date_naissance < 29 THEN 1
WHEN t_datim_diaginfo.cl2v > 0 AND date_sortie - date_naissance >= 29 AND age = 0 THEN 1
WHEN t_datim_diaginfo.cl3v > 0 AND age >= 1 AND age < 10 THEN 1
WHEN t_datim_diaginfo.cl4v > 0 AND age >= 10 AND age < 20 THEN 1
WHEN t_datim_diaginfo.cl5v > 0 AND age >= 20 AND age < 65 THEN 1
WHEN t_datim_diaginfo.cl6v > 0 AND age >= 65 THEN 1
ELSE 0 END,
diagnostic_relie_datim_cl1v = t_datim_diaginfo.cl1v,
diagnostic_relie_datim_cl2v = t_datim_diaginfo.cl2v,
diagnostic_relie_datim_cl3v = t_datim_diaginfo.cl3v,
diagnostic_relie_datim_cl4v = t_datim_diaginfo.cl4v,
diagnostic_relie_datim_cl5v = t_datim_diaginfo.cl5v,
diagnostic_relie_datim_cl6v = t_datim_diaginfo.cl6v,
diagnostic_relie_datim_compimprecis = t_datim_diaginfo.compimprecis
FROM pmsi.t_datim_diaginfo
WHERE diagnostic_relie_id = t_datim_diaginfo.diagnostic_id AND
date_sortie BETWEEN date_debut AND date_fin AND
(
t_datim_diaginfo.rare <> 0 OR
t_datim_diaginfo.dpchir <> 0 OR
t_datim_diaginfo.zinhab <> 0 OR
t_datim_diaginfo.imprecis <> 0 OR
t_datim_diaginfo.zaffchr <> 0 OR
t_datim_diaginfo.timprecis <> 0 OR
t_datim_diaginfo.tintox <> 0 OR
t_datim_diaginfo.cma <> 0 OR
t_datim_diaginfo.cti_cma_fils <> 0 OR
t_datim_diaginfo.cti_cma_frere <> 0 OR
t_datim_diaginfo.dpacte <> 0 OR
t_datim_diaginfo.dgcpt669 <> 0 OR
t_datim_diaginfo.brulure <> 0 OR
t_datim_diaginfo.esth <> 0 OR
t_datim_diaginfo.affaig <> 0 OR
t_datim_diaginfo.sexed <> 0 OR
t_datim_diaginfo.cl1v <> 0 OR
t_datim_diaginfo.cl2v <> 0 OR
t_datim_diaginfo.cl3v <> 0 OR
t_datim_diaginfo.cl4v <> 0 OR
t_datim_diaginfo.cl5v <> 0 OR
t_datim_diaginfo.cl6v <> 0 OR
t_datim_diaginfo.compimprecis <> 0
)
;
RAISE NOTICE '%','Association DATIM DA';
DROP TABLE IF EXISTS w_rss_diagnostics_associes;
CREATE TEMP TABLE w_rss_diagnostics_associes AS
SELECT
w_rss.rss_id,
COALESCE(t_diagnostics.code,'') AS diagnostic_associe_code,
COALESCE(t_datim_diaginfo.cma,0) AS diagnostic_associe_datim_cma,
COALESCE(t_datim_diaginfo.cti_cma_fils,0) AS diagnostic_associe_datim_cti_cma_fils,
COALESCE(t_datim_diaginfo.cti_cma_frere,0) AS diagnostic_associe_datim_cti_cma_frere,
COALESCE(t_datim_diaginfo.rare,0) AS diagnostic_associe_datim_rare,
COALESCE(t_datim_diaginfo.imprecis,0) AS diagnostic_associe_datim_imprecis,
COALESCE(t_datim_diaginfo.tintox,0) AS diagnostic_associe_datim_tintox,
COALESCE(t_datim_diaginfo.brulure,0) AS diagnostic_associe_datim_brulure,
COALESCE(t_datim_diaginfo.brulurebis,0) AS diagnostic_associe_datim_brulurebis,
COALESCE(t_datim_diaginfo.esth,0) AS diagnostic_associe_datim_esth,
COALESCE(t_datim_diaginfo.sexed,0) AS diagnostic_associe_datim_sexed,
CASE
WHEN sexe <> 1 AND t_datim_diaginfo.sexed = 1 THEN 1
WHEN sexe <> 2 AND t_datim_diaginfo.sexed = 2 THEN 1
ELSE 0 END AS diagnostic_associe_datim_pbsexe,
COALESCE(t_datim_diaginfo.cl1v,0) AS diagnostic_associe_datim_cl1v,
COALESCE(t_datim_diaginfo.cl2v,0) AS diagnostic_associe_datim_cl2v,
COALESCE(t_datim_diaginfo.cl3v,0) AS diagnostic_associe_datim_cl3v,
COALESCE(t_datim_diaginfo.cl4v,0) AS diagnostic_associe_datim_cl4v,
COALESCE(t_datim_diaginfo.cl5v,0) AS diagnostic_associe_datim_cl5v,
COALESCE(t_datim_diaginfo.cl6v,0) AS diagnostic_associe_datim_cl6v,
COALESCE(t_datim_diaginfo.compimprecis,0) AS diagnostic_associe_datim_compimprecis,
CASE
WHEN t_datim_diaginfo.cl1v > 0 AND date_sortie - date_naissance < 29 THEN 1
WHEN t_datim_diaginfo.cl2v > 0 AND date_sortie - date_naissance >= 29 AND age = 0 THEN 1
WHEN t_datim_diaginfo.cl3v > 0 AND age >= 1 AND age < 10 THEN 1
WHEN t_datim_diaginfo.cl4v > 0 AND age >= 10 AND age < 20 THEN 1
WHEN t_datim_diaginfo.cl5v > 0 AND age >= 20 AND age < 65 THEN 1
WHEN t_datim_diaginfo.cl6v > 0 AND age >= 65 THEN 1
ELSE 0 END AS diagnostic_associe_datim_pbage
FROM w_rss
LEFT JOIN pmsi.p_rss_diagnostics ON w_rss.rss_id = p_rss_diagnostics.rss_id AND type_diagnostic = 'DA'
LEFT JOIN pmsi.t_diagnostics ON p_rss_diagnostics.diagnostic_id = t_diagnostics.oid
LEFT JOIN pmsi.t_datim_diaginfo ON p_rss_diagnostics.diagnostic_id = t_datim_diaginfo.diagnostic_id AND date_sortie BETWEEN date_debut AND date_fin
;
CREATE INDEX w_rss_diagnostics_associes_i1 ON w_rss_diagnostics_associes USING btree (rss_id);
CREATE INDEX w_rss_diagnostics_associes_i2 ON w_rss_diagnostics_associes USING btree (diagnostic_associe_code);
DROP TABLE IF EXISTS w_brulure;
CREATE TEMP TABLE w_brulure AS
SELECT
rss_id,
max(w_rss_diagnostics_associes.diagnostic_associe_datim_brulurebis) as brulure
FROM
w_rss_diagnostics_associes
GROUP BY rss_id;
UPDATE w_rss SET
diagnostic_associe_brulure = brulure
FROM
w_brulure
WHERE
w_brulure.rss_id = w_rss.rss_id
AND diagnostic_associe_brulure <> brulure;
RAISE NOTICE '%','Association Diagnostics documentaires';
DROP TABLE IF EXISTS w_rss_diagnostics_documentaires;
CREATE TEMP TABLE w_rss_diagnostics_documentaires AS
SELECT
w_rss.rss_id,
COALESCE(t_diagnostics.code,'') AS diagnostic_documentaire_code
FROM w_rss
JOIN pmsi.p_rss_diagnostics ON w_rss.rss_id = p_rss_diagnostics.rss_id AND type_diagnostic = 'DD'
JOIN pmsi.t_diagnostics ON p_rss_diagnostics.diagnostic_id = t_diagnostics.oid
;
CREATE INDEX w_rss_diagnostics_documentaires_i1 ON w_rss_diagnostics_documentaires USING btree (rss_id);
CREATE INDEX w_rss_diagnostics_documentaires_i2 ON w_rss_diagnostics_documentaires USING btree (diagnostic_documentaire_code);
RAISE NOTICE '%','Diagnostics en double';
DROP TABLE IF EXISTS w_rss_diagnostics_doubles;
CREATE TEMP TABLE w_rss_diagnostics_doubles AS
SELECT
w_rss.rss_id, p_rss_diagnostics.no_rum, p_rss_diagnostics.diagnostic_id
FROM w_rss
JOIN pmsi.p_rss_diagnostics ON w_rss.rss_id = p_rss_diagnostics.rss_id
GROUP BY 1,2,3
HAVING count(*) > 1;
CREATE INDEX w_rss_diagnostics_doubles_i1 ON w_rss_diagnostics_doubles USING btree (diagnostic_id);
UPDATE w_rss
SET diagnostic_double_code = subview.diagnostic_double_code
FROM (
SELECT
rss_id,
base.cti_group_concat(t_diagnostics.code) AS diagnostic_double_code
FROM w_rss_diagnostics_doubles
JOIN pmsi.t_diagnostics ON diagnostic_id = t_diagnostics.oid
GROUP BY 1
) subview
WHERE w_rss.oid = subview.rss_id;
RAISE NOTICE '%','Concatenation des codes diagnosticss';
DROP TABLE IF EXISTS w_diag_list;
CREATE TEMP TABLE w_diag_list AS
SELECT
w_rss.oid as rss_id,
base.cti_group_concat(t_diagnostics.code) as liste_diag,
base.cti_array_accum(CASE WHEN p_rss_diagnostics.type_diagnostic_rss = 'DA' THEN t_diagnostics.oid ELSE NULL END) AS da__array
FROM
w_rss
JOIN pmsi.p_rss_diagnostics ON p_rss_diagnostics.rss_id = w_rss.oid
JOIN pmsi.t_diagnostics ON t_diagnostics.oid = p_rss_diagnostics.diagnostic_id
GROUP BY w_rss.oid;
UPDATE w_rss SET
liste_diagnostics = liste_diag,
da_array = da_array
FROM
w_diag_list
WHERE
w_diag_list.rss_id = w_rss.rss_id;
RAISE NOTICE '%','Concatenation des codes diagnosticss documentaires';
DROP TABLE IF EXISTS w_diag_doc_list;
CREATE TEMP TABLE w_diag_doc_list AS
SELECT
w_rss.oid as rss_id,
array_agg(DISTINCT t_diagnostics.code) AS dd__array
FROM
w_rss
JOIN pmsi.p_rss_diagnostics ON p_rss_diagnostics.rss_id = w_rss.oid
JOIN pmsi.t_diagnostics ON t_diagnostics.oid = p_rss_diagnostics.diagnostic_id
WHERE
p_rss_diagnostics.type_diagnostic = 'DD'
GROUP BY w_rss.oid;
UPDATE w_rss SET
diagnostics_documentaires = dd__array
FROM
w_diag_doc_list
WHERE
w_diag_doc_list.rss_id = w_rss.rss_id;
RAISE NOTICE '%','Association DATIM Actes';
DROP TABLE IF EXISTS w_rss_actes;
CREATE TEMP TABLE w_rss_actes AS
SELECT
p_rss_actes.rss_id,
COALESCE(t_actes_c.code,'') AS acte_code,
COALESCE(t_actes_c.texte,'') AS acte_texte,
COALESCE(activite_ccam,'') AS acte_activite,
COALESCE(phase_ccam,'') AS acte_phase,
COALESCE(CASE WHEN t_actes_c.classant = 'Y' THEN '1' ELSE '0' END) AS acte_classant,
CASE WHEN trim(association_nonprevue_ccam) <> ''::text THEN association_nonprevue_ccam else '0'::text END AS acte_assocnonprev,
MAX(CASE
WHEN p_rss_actes.rss_id IS NULL THEN ''
WHEN p_rss_actes.activite_ccam <> '4'::bpchar THEN t_actes_c.ccam_regroupement_code_1
ELSE t_actes_c.ccam_regroupement_code_4
END) AS acte_prestation,
MAX(COALESCE(t_datim_ccaminfo.ffm,0)) AS acte_datim_ffm,
MAX(COALESCE(t_datim_ccaminfo.se,0)) AS acte_datim_se,
MAX(COALESCE(t_datim_ccaminfo.fsd,0)) AS acte_datim_fsd,
MAX(COALESCE(t_datim_ccaminfo.autre,0)) AS acte_datim_autre,
MAX(COALESCE(t_datim_ccaminfo.unichir,0)) AS acte_datim_unichir,
MAX(COALESCE(t_datim_ccaminfo.gestcomp,0)) AS acte_datim_gestcomp,
MAX(COALESCE(t_datim_ccaminfo.reqz,0)) AS acte_datim_reqz,
MAX(COALESCE(t_datim_ccaminfo.dialyse,0)) AS acte_datim_dialyse,
MAX(COALESCE(t_datim_ccaminfo.esthe,0)) AS acte_datim_esth,
MAX(COALESCE(t_datim_ccaminfo.confort,0)) AS acte_datim_confort,
MAX(COALESCE(t_datim_ccaminfo.brule,0)) AS acte_datim_brule,
MAX(COALESCE(t_datim_ccaminfo.neurochir,0)) AS acte_datim_neurochir,
MAX(COALESCE(t_datim_ccaminfo.ojatypique,0)) AS acte_datim_0jatypique,
MAX(COALESCE(t_unites_medicales.type_autorisation,''::text)) AS acte_umaut,
MAX(COALESCE(t_datim_ccaminfo.seance,0)) AS acte_datim_seance,
MIN(date_acte) as acte_min_date_acte,
MAX(date_acte) as acte_max_date_acte,
SUM(nombre) AS acte_nombre,
0::integer as acte_nb_meme_jour
FROM w_rss
LEFT JOIN pmsi.p_rss_actes ON w_rss.rss_id = p_rss_actes.rss_id
LEFT JOIN pmsi.t_actes_c ON acte_id = t_actes_c.oid
LEFT JOIN pmsi.t_datim_ccaminfo ON t_datim_ccaminfo.acte_id = t_actes_c.oid
AND date_sortie BETWEEN date_debut AND date_fin
AND p_rss_actes.phase_ccam = substr(t_datim_ccaminfo.acte, 8,1)
LEFT JOIN pmsi.t_unites_medicales ON t_unites_medicales.oid = p_rss_actes.unite_medicale_id
GROUP BY 1,2,3,4,5,6,7;
CREATE INDEX w_rss_actes_i1 ON w_rss_actes USING btree (rss_id);
CREATE INDEX w_rss_actes_i2 ON w_rss_actes USING btree (acte_code);
-- Calcul du nombre d'actes identiques réalisés le même jour
WITH w_meme_jour AS (
SELECT
w_rss.rss_id,
t_actes.code as acte_code,
p_rss_actes.date_acte,
p_rss_actes.activite_ccam,
p_rss_actes.phase_ccam,
CASE WHEN trim(p_rss_actes.association_nonprevue_ccam) <> ''::text THEN p_rss_actes.association_nonprevue_ccam else '0'::text END as association_nonprevue_ccam,
count(*) as combien
FROM
w_rss
JOIN pmsi.p_rss_actes ON w_rss.rss_id = p_rss_actes.rss_id
JOIN pmsi.t_actes on t_actes.oid = p_rss_actes.acte_id
GROUP BY 1,2,3,4,5,6
HAVING count(*) > 1
)
UPDATE w_rss_actes SET
acte_nb_meme_jour = subview.combien_actes
FROM
(
SELECT
rss_id,
acte_code,
activite_ccam,
phase_ccam,
association_nonprevue_ccam,
sum(combien) as combien_actes
FROM
w_meme_jour
GROUP BY 1,2,3,4,5
) subview
WHERE 1=1
AND subview.rss_id = w_rss_actes.rss_id
AND subview.acte_code = w_rss_actes.acte_code
AND subview.activite_ccam = w_rss_actes.acte_activite
AND subview.phase_ccam = w_rss_actes.acte_phase
AND subview.association_nonprevue_ccam = w_rss_actes.acte_assocnonprev;
RAISE NOTICE '%','Concatenation des codes actes';
DROP TABLE IF EXISTS w_rss_actes_array;
CREATE TEMP TABLE w_rss_actes_array AS
SELECT
w_rss.rss_id,
base.cti_array_accum(p_rss_actes.acte_id) as actes_array
FROM
w_rss
JOIN pmsi.p_rss_actes USING (rss_id)
GROUP BY 1;
CREATE INDEX w_rss_actes_array_i1 ON w_rss_actes_array USING btree (rss_id);
UPDATE w_rss SET
acte_id_array = actes_array
FROM
w_rss_actes_array
WHERE
w_rss_actes_array.rss_id = w_rss.rss_id;
RAISE NOTICE '%','Association Prestations';
DROP TABLE IF EXISTS w_rsf_detail;
CREATE TEMP TABLE w_rsf_detail AS
SELECT
p_rsf_detail.rss_id,
COALESCE(t_prestations.code,'') AS presta_code,
COALESCE(to_char(t_ghs.code,'FM0000'),'') AS presta_ghs,
SUM(nombre*coefficient) AS presta_nombre,
SUM(p_rsf_detail.base_remboursement) AS presta_facture,
SUM(p_rsf_detail.sejour_remboursable) AS presta_rembourse
FROM w_rss
LEFT JOIN pmsi.p_rsf_detail ON w_rss.rss_id = p_rsf_detail.rss_id
LEFT JOIN pmsi.t_ghs ON p_rsf_detail.ghs_id = t_ghs.oid
LEFT JOIN pmsi.t_prestations ON prestation_id = t_prestations.oid
GROUP BY 1,2,3;
CREATE INDEX w_rsf_detail_i1 ON w_rsf_detail USING btree (rss_id);
CREATE INDEX w_rsf_detail_i2 ON w_rsf_detail USING btree (presta_code);
RAISE NOTICE '%','Recuperation pathologies chroniques';
DROP TABLE IF EXISTS w_patients_pathologies_chroniques;
CREATE TEMP TABLE w_patients_pathologies_chroniques AS
SELECT
patient_id,
Array[
MAX(CASE t_listes.code WHEN 'CTI_EXPCHR01_D' THEN 1 ELSE 0 END),
MAX(CASE t_listes.code WHEN 'CTI_EXPCHR02_D' THEN 1 ELSE 0 END),
MAX(CASE t_listes.code WHEN 'CTI_EXPCHR03_D' THEN 1 ELSE 0 END),
MAX(CASE t_listes.code WHEN 'CTI_EXPCHR04_D' THEN 1 ELSE 0 END),
MAX(CASE t_listes.code WHEN 'CTI_EXPCHR05_D' THEN 1 ELSE 0 END),
MAX(CASE t_listes.code WHEN 'CTI_EXPCHR06_D' THEN 1 ELSE 0 END),
MAX(CASE t_listes.code WHEN 'CTI_EXPCHR07_D' THEN 1 ELSE 0 END),
MAX(CASE t_listes.code WHEN 'CTI_EXPCHR08_D' THEN 1 ELSE 0 END),
MAX(CASE t_listes.code WHEN 'CTI_EXPCHR09_D' THEN 1 ELSE 0 END),
MAX(CASE t_listes.code WHEN 'CTI_EXPCHR99_D' THEN 1 ELSE 0 END)
] AS pathologies_chroniques
FROM pmsi.p_rss
LEFT JOIN pmsi.p_rss_diagnostics ON rss_id = p_rss.oid
LEFT JOIN pmsi.t_listes_contenu ON diagnostic_id = to_id
LEFT JOIN pmsi.t_listes ON liste_id = t_listes.oid AND
t_listes.code LIKE 'CTI_EXPCHR%' AND
t_listes.code LIKE '%D'
WHERE ghm_id <> 0
GROUP BY 1
HAVING count(DISTINCT rss_id) > 1 AND
count(t_listes.oid) > 0;
CREATE INDEX w_patients_pathologies_chroniques_i1 ON w_patients_pathologies_chroniques USING btree (patient_id);
DROP TABLE IF EXISTS w_rss_pathologies_chroniques;
CREATE TEMP TABLE w_rss_pathologies_chroniques AS
SELECT
w_rss.rss_id, w_rss.no_rss,
w_rss.patient_id,
Array[
CASE WHEN MAX(CASE t_listes.code WHEN 'CTI_EXPCHR01_D' THEN 1 ELSE 0 END) < MAX(pathologies_chroniques[1]) THEN 1 ELSE 0 END,
CASE WHEN MAX(CASE t_listes.code WHEN 'CTI_EXPCHR02_D' THEN 1 ELSE 0 END) < MAX(pathologies_chroniques[2]) THEN 1 ELSE 0 END,
CASE WHEN MAX(CASE t_listes.code WHEN 'CTI_EXPCHR03_D' THEN 1 ELSE 0 END) < MAX(pathologies_chroniques[3]) THEN 1 ELSE 0 END,
CASE WHEN MAX(CASE t_listes.code WHEN 'CTI_EXPCHR04_D' THEN 1 ELSE 0 END) < MAX(pathologies_chroniques[4]) THEN 1 ELSE 0 END,
CASE WHEN MAX(CASE t_listes.code WHEN 'CTI_EXPCHR05_D' THEN 1 ELSE 0 END) < MAX(pathologies_chroniques[5]) THEN 1 ELSE 0 END,
CASE WHEN MAX(CASE t_listes.code WHEN 'CTI_EXPCHR06_D' THEN 1 ELSE 0 END) < MAX(pathologies_chroniques[6]) THEN 1 ELSE 0 END,
CASE WHEN MAX(CASE t_listes.code WHEN 'CTI_EXPCHR07_D' THEN 1 ELSE 0 END) < MAX(pathologies_chroniques[7]) THEN 1 ELSE 0 END,
CASE WHEN MAX(CASE t_listes.code WHEN 'CTI_EXPCHR08_D' THEN 1 ELSE 0 END) < MAX(pathologies_chroniques[8]) THEN 1 ELSE 0 END,
CASE WHEN MAX(CASE t_listes.code WHEN 'CTI_EXPCHR09_D' THEN 1 ELSE 0 END) < MAX(pathologies_chroniques[9]) THEN 1 ELSE 0 END,
CASE WHEN MAX(CASE t_listes.code WHEN 'CTI_EXPCHR99_D' THEN 1 ELSE 0 END) < MAX(pathologies_chroniques[10]) THEN 1 ELSE 0 END
] AS pathologies_chroniques_non_codees
FROM w_rss
JOIN w_patients_pathologies_chroniques ON w_rss.patient_id = w_patients_pathologies_chroniques.patient_id
LEFT JOIN pmsi.p_rss_diagnostics ON p_rss_diagnostics.rss_id = w_rss.rss_id
LEFT JOIN pmsi.t_listes_contenu ON diagnostic_id = to_id
LEFT JOIN pmsi.t_listes ON liste_id = t_listes.oid AND
t_listes.code LIKE 'CTI_EXPCHR%' AND
t_listes.code LIKE '%D'
WHERE ghm_id <> 0
GROUP BY 1,2,3;
CREATE INDEX w_rss_pathologies_chroniques_i1 ON w_rss_pathologies_chroniques USING btree (rss_id);
UPDATE w_rss
SET pathologies_chroniques_non_codees = w_rss_pathologies_chroniques.pathologies_chroniques_non_codees
FROM w_rss_pathologies_chroniques
WHERE w_rss_pathologies_chroniques.rss_id = w_rss.rss_id;
RAISE NOTICE '%','Recuperation sejour precedent';
DROP TABLE IF EXISTS w_rss_precedent;
CREATE TEMP TABLE w_rss_precedent AS
SELECT
w_rss_rss_id,
(MAX(Array[p_rss_date_sortie::text, p_rss_rss_id::text]))[2]::bigint AS sejour_precedent_rss_id
FROM
(
SELECT
w_rss.rss_id AS w_rss_rss_id,
w_rss.date_entree AS w_rss_date_entree,
w_rss.date_sortie AS w_rss_date_sortie,
p_rss.oid AS p_rss_rss_id,
p_rss.date_entree AS p_rss_date_entree,
p_rss.date_sortie AS p_rss_date_sortie
FROM w_rss
JOIN pmsi.p_rss ON w_rss.patient_id = p_rss.patient_id AND
w_rss.finess = p_rss.finess
JOIN pmsi.t_ghm_c ON p_rss.ghm_id = t_ghm_c.oid
WHERE p_rss.oid <> w_rss.rss_id AND
w_rss.patient_id <> 0 AND
w_rss.ghm_id <> 0 AND
w_rss.cmd_code NOT IN ('28','90','99') AND
p_rss.ghm_id <> 0 AND
p_rss.date_entree < w_rss.date_sortie AND
p_rss.etat = '' AND
p_rss.ghm_id <> 0 AND
t_ghm_c.cmd_code NOT IN ('28','90','99')
) subview
GROUP BY 1;
UPDATE w_rss SET
sejour_precedent_rss_id = w_rss_precedent.sejour_precedent_rss_id,
sejour_precedent_date_entree = p_rss.date_entree,
sejour_precedent_date_sortie = p_rss.date_sortie,
sejour_precedent_ghm_code = t_ghm.code
FROM w_rss_precedent
JOIN pmsi.p_rss ON p_rss.oid = sejour_precedent_rss_id
JOIN pmsi.t_ghm ON ghm_id = t_ghm.oid
WHERE w_rss_precedent.w_rss_rss_id = w_rss.rss_id;
RAISE NOTICE '%','Recuperation GHM RSA';
UPDATE w_rss SET
ghmrsa_id = p_rsa.ghm_id,
ghmrsa_code = t_ghm.code,
ghsrsa_id = p_rsa.ghs_genrsa_id,
ghsrsa_code = t_ghs.code,
nb_exh_rsa = p_rsa.nb_exh
FROM pmsi.p_rsa
LEFT JOIN pmsi.t_ghm ON p_rsa.ghm_genrsa_id = t_ghm.oid
LEFT JOIN pmsi.t_ghs ON p_rsa.ghs_genrsa_id = t_ghs.oid
WHERE p_rsa.rss_id = w_rss.oid AND
(
ghmrsa_id IS DISTINCT FROM p_rsa.ghm_id OR
nb_exh_rsa IS DISTINCT FROM p_rsa.nb_exh OR
ghsrsa_id IS DISTINCT FROM p_rsa.ghs_genrsa_id
)
;
UPDATE w_rss SET
ghmrsa_in_id = p_rsa.ghm_id,
ghmrsa_in_code = t_ghm.code
FROM pmsi.p_rsa
LEFT JOIN pmsi.t_ghm ON p_rsa.ghm_id = t_ghm.oid
WHERE p_rsa.rss_id = w_rss.oid AND
(
ghmrsa_in_id IS DISTINCT FROM p_rsa.ghm_id
)
;
UPDATE w_rss SET
ghmrsa_id = w_rss.ghm_id,
ghmrsa_code = w_rss.ghm_code,
ghsrsa_id = w_rss.ghs_id,
ghsrsa_code = w_rss.ghs_code,
nb_exh_rsa = w_rss.nb_exh
WHERE ghsrsa_id = 0
;
-- Sauvegarde tables en cache
RAISE NOTICE '%','Cache tables';
DROP TABLE IF EXISTS cache.pmsi_expert_cache_rss;
CREATE TABLE cache.pmsi_expert_cache_rss AS SELECT * FROM w_rss;
DROP TABLE IF EXISTS cache.pmsi_expert_cache_rss_diagnostics_associes;
CREATE TABLE cache.pmsi_expert_cache_rss_diagnostics_associes AS SELECT * FROM w_rss_diagnostics_associes;
DROP TABLE IF EXISTS cache.pmsi_expert_cache_rss_actes;
CREATE TABLE cache.pmsi_expert_cache_rss_actes AS SELECT * FROM w_rss_actes;
DROP TABLE IF EXISTS cache.pmsi_expert_cache_rsf_detail;
CREATE TABLE cache.pmsi_expert_cache_rsf_detail AS SELECT * FROM w_rsf_detail;
DROP TABLE IF EXISTS cache.pmsi_expert_cache_rss_precedent;
CREATE TABLE cache.pmsi_expert_cache_rss_precedent AS SELECT * FROM w_rss_precedent;
END IF;
-- Si utilisation du cache, récupérer les caches
IF _use_cache = '1' THEN
RAISE NOTICE '%','Recuperation Cache tables';
DROP TABLE IF EXISTS w_rss;
CREATE TEMP TABLE w_rss AS SELECT * FROM cache.pmsi_expert_cache_rss;
CREATE INDEX w_rss_i1 ON w_rss USING btree (oid);
CREATE INDEX w_rss_i2 ON w_rss USING btree (diagnostic_principal_code);
CREATE INDEX w_rss_i3 ON w_rss USING btree (diagnostic_relie_code);
CREATE INDEX w_rss_i4 ON w_rss USING btree (acte_principal_code);
CREATE INDEX w_rss_i5 ON w_rss USING btree (annee_sortie);
DROP TABLE IF EXISTS w_rss_diagnostics_associes;
CREATE TEMP TABLE w_rss_diagnostics_associes AS SELECT * FROM cache.pmsi_expert_cache_rss_diagnostics_associes;
CREATE INDEX w_rss_diagnostics_associes_i1 ON w_rss_diagnostics_associes USING btree (rss_id);
CREATE INDEX w_rss_diagnostics_associes_i2 ON w_rss_diagnostics_associes USING btree (diagnostic_associe_code);
DROP TABLE IF EXISTS w_rss_actes;
CREATE TEMP TABLE w_rss_actes AS SELECT * FROM cache.pmsi_expert_cache_rss_actes;
CREATE INDEX w_rss_actes_i1 ON w_rss_actes USING btree (rss_id);
CREATE INDEX w_rss_actes_i2 ON w_rss_actes USING btree (acte_code);
DROP TABLE IF EXISTS w_rsf_detail;
CREATE TEMP TABLE w_rsf_detail AS SELECT * FROM cache.pmsi_expert_cache_rsf_detail;
CREATE INDEX w_rsf_detail_i1 ON w_rsf_detail USING btree (rss_id);
CREATE INDEX w_rsf_detail_i2 ON w_rsf_detail USING btree (presta_code);
DROP TABLE IF EXISTS w_rss_precedent;
CREATE TEMP TABLE w_rss_precedent AS SELECT * FROM cache.pmsi_expert_cache_rss_precedent;
END IF;
RAISE NOTICE '%','Tests DATIM';
-- Creation table de travail
DROP TABLE IF EXISTS temp.w_expert_rss_controle;
PERFORM base.cti_create_table_from('temp', 'w_expert_rss_controle', 'pmsi', 'p_expert_rss_controle');
CREATE INDEX i_expert_rss_controle_w1 ON temp.w_expert_rss_controle USING btree (rss_id);
-- Initialisation tables des regles
INSERT INTO pmsi.t_expert_controle_rule(controle_id, numero, sqlcmd_where, sqlcmd_justificatif)
SELECT
t_expert_controle.oid AS controle_id, 1::bigint AS numero, ''::text AS sqlcmd_where, ''::text AS sqlcmd_justificatif
FROM pmsi.t_expert_controle
LEFT JOIN pmsi.t_expert_controle_rule ON controle_id = t_expert_controle.oid
WHERE t_expert_controle_rule IS NULL;
ANALYSE w_rss;
-- Menage dans l'historique
DELETE FROM pmsi.p_expert_rss_controle
USING pmsi.t_divers
WHERE t_divers.code = 'EXPERT_DATE_DEBUT' AND
date_sortie <= t_divers.valeur_date AND
date_sortie < (date_trunc('year',now())-interval '1 year')
;
-- DEMARRAGE DES TESTS
RAISE NOTICE '%','Tests';
TRUNCATE temp.w_expert_rss_controle;
UPDATE pmsi.t_expert_controle_rule SET
last_execution_date = NULL,
last_execution_ok = '1'
WHERE (oid = i_controle_id OR i_controle_id IS NULL) AND
(last_execution_date IS DISTINCT FROM NULL OR
last_execution_ok IS DISTINCT FROM '1');
request := 'SELECT t_expert_controle.code, controle_id, t_expert_controle_rule.oid, sqlcmd_where, sqlcmd_justificatif
FROM pmsi.t_expert_controle_rule
JOIN pmsi.t_expert_controle ON t_expert_controle_rule.controle_id = t_expert_controle.oid
WHERE trim(sqlcmd_where) <> '''' AND is_global IS DISTINCT FROM ''1'' AND
(t_expert_controle.code = ''CTI007'' OR t_expert_controle.code <> ''CTI007'') ';
if (i_controle_id IS NOT NULL) THEN
request = request || ' AND t_expert_controle.oid = ' || i_controle_id;
END IF;
OPEN ref FOR
EXECUTE request;
LOOP
FETCH ref INTO _controle_code, _controle_id, _controle_rule_id, _sqlcmd_where, _sqlcmd_justificatif;
IF NOT FOUND THEN
EXIT;
END IF;
IF trim(_sqlcmd_justificatif) = '' THEN
_sqlcmd_justificatif = '''''';
END IF;
_sqlcmd_justificatif = replace(_sqlcmd_justificatif,'][',']||'', ''||[');
_sqlcmd_justificatif = replace(_sqlcmd_justificatif,'] [',']||'', ''||[');
_nb_rules = _nb_rules + 1;
-- Transformation raccourcis
_sqlcmd_new_where = _sqlcmd_where;
_subviews_count = 0;
-- Raccourcis sans valeur
_sqlcmd_new_where = replace(_sqlcmd_new_where,'[PMSI=0]','w_rss.ghm_id = 0');
_sqlcmd_new_where = replace(_sqlcmd_new_where,'[PMSI=1]','w_rss.ghm_id <> 0');
_sqlcmd_new_where = replace(_sqlcmd_new_where,'[ENCOURS=0]','w_rss.en_cours = ''0''');
_sqlcmd_new_where = replace(_sqlcmd_new_where,'[ENCOURS=1]','w_rss.en_cours <> ''0''');
-- Raccourcis avec valeurs saisies
_sqlcmd_new_where = replace(_sqlcmd_new_where,chr(9),' ');
_sqlcmd_new_where = replace(_sqlcmd_new_where,chr(10),' ');
_sqlcmd_new_where = replace(_sqlcmd_new_where,chr(13),' ');
_d = 1;
LOOP
RAISE NOTICE 'DEBUG %' , _sqlcmd_new_where;
RAISE NOTICE 'DEBUG %' , 'D='||_d::text;
-- Recherche chaine de controle
_p = position('[' IN substr(_sqlcmd_new_where,_d));
IF _p <= 0 THEN
EXIT;
END IF;
RAISE NOTICE 'DEBUG %' , 'P='||_p::text;
IF _p > 0 THEN
_p = _d + _p - 1;
_i = _p + 1;
_c = 1;
_f = 0;
<<test>>
LOOP
IF _i > length(_sqlcmd_new_where) THEN
EXIT;
END IF;
IF substr(_sqlcmd_new_where,_i,1) = '[' THEN
_c = _c + 1;
END IF;
IF substr(_sqlcmd_new_where,_i,1) = ']' THEN
_c = _c - 1;
END IF;
IF _c = 0 THEN
_f = _i;
EXIT test;
END IF;
_i = _i + 1;
END LOOP test;
--_f = position(']' IN substr(_sqlcmd_new_where,_p));
IF _f <= 0 THEN
EXIT;
END IF;
--_f = _p + _f - 1;
_l = _f - _p + 1;
_ctl_string = substr(_sqlcmd_new_where,_p+1,_l-2);
RAISE NOTICE 'DEBUG %' , _ctl_string;
_d = _f;
-- Recherche champ et valeurs
_ctl_field = '';
_ctl_operator = '';
_ctl_values = '';
_ctl_values_2 = '';
_x = 0;
_y = 0;
_e = 0;
_ctl_rule_i = 0;
WHILE _x < length(_ctl_string) LOOP
_x = _x + 1;
IF substr(_ctl_string,_x,1) ='&' THEN
_e = 0;
_ctl_field = '';
ELSE
IF substr(_ctl_string,_x,1) IN ('=','<','>') THEN
_ctl_rule_i = _ctl_rule_i + 1;
_ctl_rule_fields_array[_ctl_rule_i] = _ctl_field;
_ctl_rule_operators_array[_ctl_rule_i] = '';
_ctl_rule_values_array[_ctl_rule_i] = '';
IF substr(_ctl_string,_x+1,1) IN ('=','<','>') THEN
_ctl_rule_operators_array[_ctl_rule_i] = substr(_ctl_string,_x,2);
_x = _x + 1;
ELSE
_ctl_rule_operators_array[_ctl_rule_i] = substr(_ctl_string,_x,1);
END IF;
_ctl_values = '';
_e = 2;
ELSE
IF _e = 0 THEN
_ctl_field = _ctl_field || substr(_ctl_string,_x,1);
END IF;
IF _e = 2 THEN
_ctl_rule_values_array[_ctl_rule_i] = _ctl_rule_values_array[_ctl_rule_i] || substr(_ctl_string,_x,1);
END IF;
END IF;
END IF;
END LOOP;
_ctl_new_where = '';
_x = 0;
WHILE _x < _ctl_rule_i LOOP
_x = _x + 1;
_ctl_field = trim(_ctl_rule_fields_array[_x]);
_ctl_operator = trim(_ctl_rule_operators_array[_x]);
_ctl_operator_2 = _ctl_operator;
_ctl_values = trim(_ctl_rule_values_array[_x]);
_ctl_subview_operator = '>';
_ctl_subview_value = 0;
_ctl_field = trim(_ctl_field);
_ctl_field_key = '[' || _ctl_field || ']';
_ctl_fieldType = '';
_ctl_fieldDelimiter = '';
-- Forcer type de champ
IF _ctl_field IN ('MODENT','PROV', 'DEST','MODSOR', 'DEST', 'RETGRP', 'CMD', 'CCAM:activite', 'CCAM:phase')
THEN
_ctl_fieldType = 'text';
END IF;
IF _ctl_operator <> '' THEN
_ctl_operator_2 = '>';
-- Opérateur Spécial si diag ou actes
IF _ctl_field ILIKE 'DIAGA' OR _ctl_field ILIKE 'DIAGA:%' OR
_ctl_field ILIKE 'DIAGD' OR _ctl_field ILIKE 'DIAGD:%' OR
_ctl_field LIKE 'CCAM' OR _ctl_field LIKE 'CCAM%' THEN
IF _ctl_operator = '<>' AND _x = 1 THEN
_ctl_operator = '=';
_ctl_subview_operator = '=';
END IF;
END IF;
IF _ctl_values = '' THEN
_ctl_values = '#blanc';
END IF;
IF _ctl_values <> '' THEN
_ctl_values_array = string_to_array(_ctl_values,',');
-- Values = LISTE de GHM
_i = 1;
_ctl_new_where_un = '';
LOOP
IF _i > array_upper (_ctl_values_array, 1) THEN
EXIT;
END IF;
_ctl_value = _ctl_values_array[_i];
IF _ctl_value LIKE '{%' THEN
_ctl_list = replace(replace(_ctl_value, '{', ''),'}','');
IF _ctl_field LIKE 'GHM' THEN
_ctl_list_array =
(SELECT base.cti_array_accum(t_ghm.code)
FROM pmsi.t_listes
JOIN pmsi.t_listes_contenu ON liste_id = t_listes.oid
JOIN pmsi.t_ghm ON to_id = t_ghm.oid
WHERE t_listes.code = _ctl_list);
_ctl_values_array = array_cat(_ctl_values_array, _ctl_list_array);
ELSIF _ctl_field LIKE 'PRESTA' THEN
_ctl_list_array =
(SELECT base.cti_array_accum(t_prestations.code)
FROM pmsi.t_listes
JOIN pmsi.t_listes_contenu ON liste_id = t_listes.oid
JOIN pmsi.t_prestations ON to_id = t_prestations.oid
WHERE t_listes.code = _ctl_list);
_ctl_values_array = array_cat(_ctl_values_array, _ctl_list_array);
ELSIF _ctl_field LIKE 'GHS' THEN
_ctl_list_array =
(SELECT base.cti_array_accum(t_ghs.code::text)
FROM pmsi.t_listes
JOIN pmsi.t_listes_contenu ON liste_id = t_listes.oid
JOIN pmsi.t_ghs ON to_id = t_ghs.oid
WHERE t_listes.code = _ctl_list);
_ctl_values_array = array_cat(_ctl_values_array, _ctl_list_array);
ELSIF _ctl_field LIKE 'DIAG%' THEN
_ctl_list_array =
(SELECT base.cti_array_accum(t_diagnostics.code::text)
FROM pmsi.t_listes
JOIN pmsi.t_listes_contenu ON liste_id = t_listes.oid
JOIN pmsi.t_diagnostics ON to_id = t_diagnostics.oid
WHERE t_listes.code = _ctl_list);
_ctl_values_array = array_cat(_ctl_values_array, _ctl_list_array);
END IF;
END IF;
_i = _i + 1;
END LOOP;
-- Traduction values en LIKE
_i = 1;
_ctl_new_where_un = '';
LOOP
IF _i > array_upper (_ctl_values_array, 1) THEN
EXIT;
END IF;
_ctl_value = _ctl_values_array[_i];
IF _ctl_new_where_un <> '' THEN
IF _ctl_operator = 'ILIKE' OR _ctl_operator = '=' THEN
_ctl_new_where_un = _ctl_new_where_un || ' OR ';
ELSE
_ctl_new_where_un = _ctl_new_where_un || ' AND ';
END IF;
END IF;
_ctl_fieldDelimiter = '''';
IF (_ctl_value ~ '^([0-9,-,+]+[.]?[0-9]*|[.][0-9]+)$' AND _ctl_fieldType != 'text' OR
_ctl_value LIKE '[%'
) THEN
_ctl_fieldDelimiter = '';
ELSE
IF _ctl_operator = '=' THEN
_ctl_operator = 'ILIKE';
END IF;
IF _ctl_operator = '<>' THEN
_ctl_operator = 'NOT ILIKE';
END IF;
END IF;
IF _ctl_operator = 'ILIKE' OR _ctl_operator = 'NOT ILIKE' THEN
IF _ctl_value <> '#blanc' THEN
_ctl_value = replace(_ctl_value,'*','%');
ELSE
_ctl_value = '';
END IF;
END IF;
-- Clause where traduite
_ctl_new_where_un = _ctl_new_where_un || _ctl_field_key || ' ' || _ctl_operator || ' ' || _ctl_fieldDelimiter || _ctl_value || _ctl_fieldDelimiter;
_i = _i + 1;
END LOOP;
IF _ctl_field ILIKE '%COUNT' THEN
_ctl_new_where_un = '1 = 1';
_ctl_subview_operator = _ctl_operator;
_ctl_subview_value = _ctl_value;
END IF;
IF _ctl_new_where_un <> '1 = 1' OR _ctl_new_where = '' THEN
IF _ctl_new_where <> '' THEN
_ctl_new_where = _ctl_new_where || ' AND ';
END IF;
_ctl_new_where = _ctl_new_where || ' (' || _ctl_new_where_un || ') ';
END IF;
END IF;
END IF;
END LOOP;
_ctl_field = trim(_ctl_rule_fields_array[_x]);
_ctl_field_key = '[' || _ctl_field || ']';
IF _ctl_new_where <> '' THEN
-- sous requetes (Diagnostics Associes)
IF _ctl_field ILIKE 'DIAGA' OR _ctl_field ILIKE 'DIAGA:%' THEN
_subviews_count = _subviews_count + 1;
_subviews_key[_subviews_count] = _ctl_field_key;
_subviews[_subviews_count] =
'JOIN (SELECT w_rss.rss_id AS subview' || _subviews_count::text || '_rss_id,
COALESCE(count(w_rss_diagnostics_associes),0) AS subview' || _subviews_count::text || '_count,
COALESCE(base.cti_group_concat(DISTINCT diagnostic_associe_code),'''') AS subview' || _subviews_count::text || '_code
FROM w_rss
LEFT JOIN w_rss_diagnostics_associes ON w_rss.rss_id = w_rss_diagnostics_associes.rss_id AND
' || _ctl_new_where || '
GROUP BY 1
) subview' || _subviews_count::text || '
ON subview' || _subviews_count::text || '.subview' || _subviews_count::text || '_rss_id = w_rss.rss_id ';
-- Mots clés dans justificatif issus des sous requetes
_sqlcmd_justificatif = replace(_sqlcmd_justificatif, _ctl_field_key, '''DA:''||subview' || _subviews_count::text || '_code');
_sqlcmd_justificatif = replace(_sqlcmd_justificatif, '[' || _ctl_string || ']', '''DA:''||subview' || _subviews_count::text || '_code');
_sqlcmd_justificatif = replace(_sqlcmd_justificatif, '[DIAGA]', '''DA:''||subview' || _subviews_count::text || '_code');
_ctl_field_key = 'subview' || _subviews_count::text || '_count';
_ctl_operator = _ctl_subview_operator;
_ctl_fieldDelimiter = '';
_ctl_value = _ctl_subview_value;
_ctl_new_where = '(' || _ctl_field_key || ' ' || _ctl_operator || ' ' || _ctl_value || ')';
END IF;
-- sous requetes (Diagnostics Documentaires)
IF _ctl_field ILIKE 'DIAGD' OR _ctl_field ILIKE 'DIAGD:%' THEN
_subviews_count = _subviews_count + 1;
_subviews_key[_subviews_count] = _ctl_field_key;
_subviews[_subviews_count] =
'JOIN (SELECT w_rss.rss_id AS subview' || _subviews_count::text || '_rss_id,
COALESCE(count(w_rss_diagnostics_documentaires),0) AS subview' || _subviews_count::text || '_count,
COALESCE(base.cti_group_concat(DISTINCT diagnostic_documentaire_code),'''') AS subview' || _subviews_count::text || '_code
FROM w_rss
LEFT JOIN w_rss_diagnostics_documentaires ON w_rss.rss_id = w_rss_diagnostics_documentaires.rss_id AND
' || _ctl_new_where || '
GROUP BY 1
) subview' || _subviews_count::text || '
ON subview' || _subviews_count::text || '.subview' || _subviews_count::text || '_rss_id = w_rss.rss_id ';
-- Mots clés dans justificatif issus des sous requetes
_sqlcmd_justificatif = replace(_sqlcmd_justificatif, _ctl_field_key, '''DD:''||subview' || _subviews_count::text || '_code');
_sqlcmd_justificatif = replace(_sqlcmd_justificatif, '[' || _ctl_string || ']', '''DD:''||subview' || _subviews_count::text || '_code');
_sqlcmd_justificatif = replace(_sqlcmd_justificatif, '[DIAGD]', '''DD:''||subview' || _subviews_count::text || '_code');
_ctl_field_key = 'subview' || _subviews_count::text || '_count';
_ctl_operator = _ctl_subview_operator;
_ctl_fieldDelimiter = '';
_ctl_value = _ctl_subview_value;
_ctl_new_where = '(' || _ctl_field_key || ' ' || _ctl_operator || ' ' || _ctl_value || ')';
END IF;
-- sous requetes (Actes)
IF _ctl_field LIKE 'CCAM' OR _ctl_field LIKE 'CCAM%' THEN
_subviews_count = _subviews_count + 1;
_subviews_key[_subviews_count] = _ctl_field_key;
_subviews[_subviews_count] =
'JOIN (SELECT w_rss.rss_id AS subview' || _subviews_count::text || '_rss_id,
COALESCE(SUM(w_rss_actes.acte_nombre),0) AS subview' || _subviews_count::text || '_count,
COALESCE(base.cti_group_concat(DISTINCT acte_code),'''') AS subview' || _subviews_count::text || '_code
FROM w_rss
LEFT JOIN w_rss_actes ON w_rss.rss_id = w_rss_actes.rss_id WHERE
' || _ctl_new_where || '
GROUP BY 1
) subview' || _subviews_count::text || '
ON subview' || _subviews_count::text || '.subview' || _subviews_count::text || '_rss_id = w_rss.rss_id ';
-- Mots clés dans justificatif issus des sous requetes
_sqlcmd_justificatif = replace(_sqlcmd_justificatif, _ctl_field_key, '''CCAM:''||subview' || _subviews_count::text || '_code');
_sqlcmd_justificatif = replace(_sqlcmd_justificatif, '[' || _ctl_string || ']', '''CCAM:''||subview' || _subviews_count::text || '_code');
_sqlcmd_justificatif = replace(_sqlcmd_justificatif, '[CCAM]', '''CCAM:''||subview' || _subviews_count::text || '_code');
_ctl_field_key = 'subview' || _subviews_count::text || '_count';
_ctl_operator = _ctl_subview_operator;
_ctl_fieldDelimiter = '';
_ctl_value = _ctl_subview_value;
_ctl_new_where = '(' || _ctl_field_key || ' ' || _ctl_operator || ' ' || _ctl_value || ')';
END IF;
-- sous requetes (Mères)
IF _ctl_field ILIKE 'MERE_CCAM' OR _ctl_field ILIKE 'MERE_CCAM:%' THEN
_subviews_count = _subviews_count + 1;
_subviews_key[_subviews_count] = _ctl_field_key;
_subviews[_subviews_count] =
'JOIN (SELECT w_rss.rss_id AS subview' || _subviews_count::text || '_rss_id,
COALESCE(SUM(w_rss_actes.acte_nombre),0) AS subview' || _subviews_count::text || '_count,
COALESCE(base.cti_group_concat(DISTINCT acte_code) || '','','''') AS subview' || _subviews_count::text || '_code
FROM w_rss
LEFT JOIN w_rss_actes ON w_rss.rss_id = w_rss_actes.rss_id WHERE
' || _ctl_new_where || '
GROUP BY 1
) subview' || _subviews_count::text || '
ON w_rss.rss_mere_id <> 0 AND subview' || _subviews_count::text || '.subview' || _subviews_count::text || '_rss_id = w_rss.rss_mere_id ';
-- Mots clés dans justificatif issus des sous requetes
_sqlcmd_justificatif = replace(_sqlcmd_justificatif, _ctl_field_key, '''CCAM:''||subview' || _subviews_count::text || '_code');
_sqlcmd_justificatif = replace(_sqlcmd_justificatif, '[' || _ctl_string || ']', '''CCAM:''||subview' || _subviews_count::text || '_code');
_sqlcmd_justificatif = replace(_sqlcmd_justificatif, '[MERE_CCAM]', '''CCAM:''||subview' || _subviews_count::text || '_code');
_ctl_field_key = 'subview' || _subviews_count::text || '_count';
_ctl_operator = _ctl_subview_operator;
_ctl_fieldDelimiter = '';
_ctl_value = _ctl_subview_value;
_ctl_new_where = '(' || _ctl_field_key || ' ' || _ctl_operator || ' ' || _ctl_value || ')';
END IF;
-- sous requetes (prestations)
IF _ctl_field ILIKE 'PRESTA' OR _ctl_field ILIKE 'PRESTA:%' THEN
_subviews_count = _subviews_count + 1;
_subviews_key[_subviews_count] = _ctl_field_key;
_subviews[_subviews_count] =
'JOIN (SELECT w_rss.rss_id AS subview' || _subviews_count::text || '_rss_id,
COALESCE(SUM(w_rsf_detail.presta_nombre),0) AS subview' || _subviews_count::text || '_count,
COALESCE(base.cti_group_concat(DISTINCT presta_code),'''') AS subview' || _subviews_count::text || '_code
FROM w_rss
LEFT JOIN w_rsf_detail ON w_rss.rss_id = w_rsf_detail.rss_id AND
' || _ctl_new_where || '
GROUP BY 1
) subview' || _subviews_count::text || '
ON subview' || _subviews_count::text || '.subview' || _subviews_count::text || '_rss_id = w_rss.rss_id ';
-- Mots clés dans justificatif issus des sous requetes
_sqlcmd_justificatif = replace(_sqlcmd_justificatif, _ctl_field_key, '''PRESTA:''||subview' || _subviews_count::text || '_code');
_sqlcmd_justificatif = replace(_sqlcmd_justificatif, '[' || _ctl_string || ']', '''PRESTA''||subview' || _subviews_count::text || '_code');
_sqlcmd_justificatif = replace(_sqlcmd_justificatif, '[PRESTA]', '''PRESTA:''||subview' || _subviews_count::text || '_code');
_ctl_field_key = 'subview' || _subviews_count::text || '_count';
_ctl_operator = _ctl_subview_operator;
_ctl_fieldDelimiter = '';
_ctl_value = _ctl_subview_value;
_ctl_new_where = '(' || _ctl_field_key || ' ' || _ctl_operator || ' ' || _ctl_value || ')';
END IF;
_sqlcmd_new_where = overlay(_sqlcmd_new_where placing _ctl_new_where from _p for _l);
_d = _p + length(_ctl_new_where);
END IF;
END IF;
END LOOP;
-- Sous requete patient précédent
IF _sqlcmd_new_where ILIKE '%[PREC:%' THEN
_subviews_count = _subviews_count + 1;
_subviews[_subviews_count] = 'LEFT JOIN w_rss w_rss_precedent ON w_rss.sejour_precedent_rss_id = w_rss_precedent.oid';
END IF;
-- Remplacement clés dans clause WHERE
_sqlcmd_new_where = pmsi.cti_expert_execute_rules_keys(_sqlcmd_new_where, 'where');
-- Mots clés restant dans justificatif
_sqlcmd_justificatif = pmsi.cti_expert_execute_rules_keys(_sqlcmd_justificatif, 'justificatif');
-- Execution
_sqlcmd_insert = 'INSERT INTO temp.w_expert_rss_controle(rss_id, controle_id, code_justificatif)
SELECT
w_rss.oid,
' || _controle_id || ', ' ||
_sqlcmd_justificatif || '
FROM
w_rss
';
IF _subviews_count > 0 THEN
FOR _i IN 1.._subviews_count LOOP
_subviews[_i] = pmsi.cti_expert_execute_rules_keys(_subviews[_i], 'where');
_sqlcmd_insert = _sqlcmd_insert || '
' || _subviews[_i];
END LOOP;
END IF;
_sqlcmd_insert = _sqlcmd_insert || ' WHERE ' || _sqlcmd_new_where;
_last_execution_ok = '1';
RAISE NOTICE 'DEBUG %' , _sqlcmd_insert;
BEGIN
EXECUTE _sqlcmd_insert;
EXCEPTION
WHEN others THEN RAISE NOTICE 'Erreur %' , _sqlcmd_insert;
_nb_rules_error = _nb_rules_error + 1;
_last_execution_ok = '0';
END;
UPDATE pmsi.t_expert_controle_rule SET
last_execution_date = now(),
last_execution_ok = _last_execution_ok
WHERE oid = _controle_rule_id;
END LOOP;
CLOSE ref;
-- VALIDATION
RAISE NOTICE '%','Validation';
-- TRAITEMENTS DE FIN
-- Génération des controles avec suffixe (désactivé)
IF 1 <> 1 THEN
INSERT INTO pmsi.t_expert_controle
(code,
texte,
texte,
texte_court,
is_datim,
code_datim,
date_validite_debut,
date_validite_fin,
section_id,
section_code,
section_texte)
SELECT
t_expert_controle.code || '_' || code_groupe,
t_expert_controle.texte || ' (' || code_groupe || ')',
t_expert_controle.texte_court || ' (' || code_groupe || ')',
t_expert_controle.is_datim,
t_expert_controle.code_datim,
t_expert_controle.date_validite_debut,
t_expert_controle.date_validite_fin,
t_expert_controle.section_id,
t_expert_controle.section_code,
t_expert_controle.section_texte
FROM temp.w_expert_rss_controle
JOIN pmsi.t_expert_controle ON controle_id = t_expert_controle.oid
LEFT JOIN pmsi.t_expert_controle t_expert_controle_groupe ON t_expert_controle_groupe.code = t_expert_controle.code || '_' || code_groupe
WHERE code_groupe <> '' AND t_expert_controle_groupe.oid IS NULL
GROUP BY 1,2,3,4,5,6,7,8,9,10;
UPDATE temp.w_expert_rss_controle
SET controle_id = t_expert_controle_groupe.oid
FROM pmsi.t_expert_controle,
pmsi.t_expert_controle t_expert_controle_groupe
WHERE controle_id = t_expert_controle.oid AND
t_expert_controle_groupe.code = t_expert_controle.code || '_' || code_groupe AND
code_groupe <> '' AND controle_id IS DISTINCT FROM t_expert_controle_groupe.oid;
END IF;
-- Actualisation rss_id
UPDATE pmsi.p_expert_rss_controle
SET rss_id = p_rss.oid
FROM pmsi.p_rss
WHERE p_rss.no_rss = p_expert_rss_controle.no_rss AND
p_rss.date_sortie = p_expert_rss_controle.date_sortie AND
p_expert_rss_controle.rss_id IS DISTINCT FROM p_rss.oid;
-- mise à jour justificatif sur atypies déjà signalées
UPDATE pmsi.p_expert_rss_controle SET
code_justificatif = w_expert_rss_controle.code_justificatif,
etat = CASE WHEN p_expert_rss_controle.etat = 'T' THEN '' ELSE p_expert_rss_controle.etat END,
date_signalement = CASE WHEN p_expert_rss_controle.etat = 'T' THEN date(now()) ELSE p_expert_rss_controle.date_signalement END,
date_correction = CASE WHEN p_expert_rss_controle.etat = '' THEN '20991231' ELSE p_expert_rss_controle.date_correction END
FROM temp.w_expert_rss_controle
WHERE w_expert_rss_controle.rss_id = p_expert_rss_controle.rss_id AND
w_expert_rss_controle.controle_id = p_expert_rss_controle.controle_id AND
(
p_expert_rss_controle.code_justificatif IS DISTINCT FROM w_expert_rss_controle.code_justificatif OR
p_expert_rss_controle.etat = 'T' OR
p_expert_rss_controle.date_correction IS DISTINCT FROM '20991231'
);
-- Pointage des atypies résolues
UPDATE pmsi.p_expert_rss_controle
SET etat = 'T',
date_correction = date(now())
FROM
(
SELECT
p_expert_rss_controle.rss_id,
p_expert_rss_controle.controle_id
FROM pmsi.p_expert_rss_controle
LEFT JOIN temp.w_expert_rss_controle ON w_expert_rss_controle.rss_id = p_expert_rss_controle.rss_id AND
w_expert_rss_controle.controle_id = p_expert_rss_controle.controle_id
WHERE p_expert_rss_controle.date_sortie >= _EXPERT_DATE_DEBUT AND
w_expert_rss_controle.rss_id IS NULL
) subview
WHERE subview.rss_id = p_expert_rss_controle.rss_id AND
subview.controle_id = p_expert_rss_controle.controle_id AND
(p_expert_rss_controle.controle_id = i_controle_id OR i_controle_id IS NULL) AND
(p_expert_rss_controle.etat IN ('','I') OR
p_expert_rss_controle.etat IN ('T') AND p_expert_rss_controle.date_correction > date(now()) OR
p_expert_rss_controle.etat IN ('T') AND p_expert_rss_controle.date_correction IS NULL
);
-- Pointage comme ignoré des erreurs non corrigées avant le changement de date début
UPDATE pmsi.p_expert_rss_controle
SET etat = 'I',
date_correction = date(now())
FROM
(
SELECT
p_expert_rss_controle.rss_id,
p_expert_rss_controle.controle_id
FROM pmsi.p_expert_rss_controle
LEFT JOIN temp.w_expert_rss_controle ON w_expert_rss_controle.rss_id = p_expert_rss_controle.rss_id AND
w_expert_rss_controle.controle_id = p_expert_rss_controle.controle_id
WHERE p_expert_rss_controle.date_sortie < _EXPERT_DATE_DEBUT AND
w_expert_rss_controle.rss_id IS NULL
) subview
WHERE subview.rss_id = p_expert_rss_controle.rss_id AND
subview.controle_id = p_expert_rss_controle.controle_id AND
(p_expert_rss_controle.controle_id = i_controle_id OR i_controle_id IS NULL) AND
p_expert_rss_controle.etat = '';
-- Ajout nouvelles atypies
INSERT INTO pmsi.p_expert_rss_controle (
rss_id,
no_rss,
date_sortie,
controle_id,
date_signalement,
no_test_datim,
nb_rss,
code_groupe,
code_justificatif,
cumul_base,
coefficient_attendu,
cumul_realise,
cumul_attendu,
borne_alerte,
etat,
date_correction
)
SELECT
w_expert_rss_controle.rss_id,
p_rss.no_rss,
p_rss.date_sortie,
w_expert_rss_controle.controle_id,
date(now()) AS date_signalement,
w_expert_rss_controle.no_test_datim,
w_expert_rss_controle.nb_rss,
w_expert_rss_controle.code_groupe,
w_expert_rss_controle.code_justificatif,
w_expert_rss_controle.cumul_base,
w_expert_rss_controle.coefficient_attendu,
w_expert_rss_controle.cumul_realise,
w_expert_rss_controle.cumul_attendu,
w_expert_rss_controle.borne_alerte,
w_expert_rss_controle.etat,
'20991231'
FROM temp.w_expert_rss_controle
JOIN pmsi.p_rss ON w_expert_rss_controle.rss_id = p_rss.oid
LEFT JOIN pmsi.p_expert_rss_controle ON w_expert_rss_controle.rss_id = p_expert_rss_controle.rss_id AND
w_expert_rss_controle.controle_id = p_expert_rss_controle.controle_id
WHERE p_expert_rss_controle.rss_id IS NULL
GROUP BY 1,2,3,4,5,6,7,8,9,10,11,12,13,14,15;
-- Garde une seule ligne (celle avec la date_signalement la plus ancienne)
DELETE FROM pmsi.p_expert_rss_controle
USING
(
SELECT rss_id,
no_rss,
controle_id,
etat,
date_correction,
(MIN(ARRAY[date_signalement::text,CTID::text]))[2] AS keepCTID
FROM pmsi.p_expert_rss_controle
GROUP BY 1,2,3,4,5
HAVING count(*) > 1
) subview
WHERE p_expert_rss_controle.rss_id = subview.rss_id AND
p_expert_rss_controle.no_rss = subview.no_rss AND
p_expert_rss_controle.controle_id = subview.controle_id AND
p_expert_rss_controle.etat = subview.etat AND
p_expert_rss_controle.date_correction = subview.date_correction AND
p_expert_rss_controle.CTID::text <> keepCTID;
ANALYSE pmsi.p_expert_rss_controle;
IF _nb_rules_error > 0 THEN
RETURN 'KO:' || _nb_rules || ' règles exécutées, ' || _nb_rules_error::text || ' erreur(s) SQL';
END IF;
RETURN 'OK:' || _nb_rules || ' règles exécutées sans erreur';
END;