|
|
-- 1/3 : Création de la table temporaire
|
|
|
DROP TABLE IF EXISTS w_dbsetup
|
|
|
;
|
|
|
|
|
|
CREATE TEMP TABLE w_dbsetup AS
|
|
|
SELECT
|
|
|
CASE WHEN t_expert_controle_rule.oid = 0 THEN t_expert_controle_rule.oid ELSE 1 END AS oid,
|
|
|
t_expert_controle.code AS controle_code,
|
|
|
t_expert_controle_rule.numero,
|
|
|
t_expert_controle_rule.sqlcmd_where,
|
|
|
t_expert_controle_rule.sqlcmd_justificatif,
|
|
|
t_expert_controle_rule.table_id as tab
|
|
|
FROM activite.t_expert_controle_rule
|
|
|
JOIN activite.t_expert_controle ON controle_id = t_expert_controle.oid
|
|
|
WHERE t_expert_controle.is_cti = '1' AND
|
|
|
t_expert_controle.code <> ''
|
|
|
ORDER BY t_expert_controle.code, t_expert_controle_rule.numero
|
|
|
LIMIT 0
|
|
|
;
|
|
|
|
|
|
-- 2/3 : Peuplement de la table temporaire
|
|
|
INSERT INTO w_dbsetup(
|
|
|
oid,
|
|
|
controle_code,
|
|
|
numero,
|
|
|
sqlcmd_where,
|
|
|
sqlcmd_justificatif,
|
|
|
tab
|
|
|
)
|
|
|
VALUES
|
|
|
(1, 'CTI_0ETS', 1, 'code_sorti = 1
|
|
|
AND nb_rubriques_c = 0
|
|
|
AND nb_rubriques_h = 0
|
|
|
AND type_sejour<>3 ', '', 2),
|
|
|
(1, 'CTI_0ETS', 2, '', '', 0),
|
|
|
(1, 'CTI_0ETS', 3, '', '', 0),
|
|
|
(1, 'CTI_AMB_DE_X_DS', 1, 'nb_ambulatoires = 1 AND date != date_sortie', '', 1),
|
|
|
(1, 'CTI_AMB_DE_X_DS', 2, '', '', 0),
|
|
|
(1, 'CTI_AMB_DE_X_DS', 3, '', '', 0),
|
|
|
(1, 'CTI_DEL_FAC_30', 1, 'SELECT v_sejours_1.sejour_id,
|
|
|
v_sejours_1.no_sejour,
|
|
|
v_sejours_1.date_sortie,
|
|
|
v_mouvements_sejour_2.est_facture
|
|
|
FROM activite.v_sejours_1
|
|
|
JOIN activite.v_mouvements_sejour_2 on v_mouvements_sejour_2.sejour_id=v_sejours_1.sejour_id
|
|
|
WHERE ((select valeur_date from activite.t_divers where code=''NOW'')- v_sejours_1.date_sortie) >30
|
|
|
AND v_mouvements_sejour_2.est_facture=''0''', '', 99),
|
|
|
(1, 'CTI_DEL_FAC_30', 2, '', '', 0),
|
|
|
(1, 'CTI_DEL_FAC_30', 3, '', '', 0),
|
|
|
(1, 'CTI_DTEXP_DTFAC', 1, 'date_expedition < date_facture', 'date_expedition, date_facture', 0),
|
|
|
(1, 'CTI_DTEXP_DTFAC', 2, '', '', 0),
|
|
|
(1, 'CTI_DTEXP_DTFAC', 3, '', '', 0),
|
|
|
(1, 'CTI_DTFAC_DTSOR', 1, 'date_facture < date_sortie and date_sortie is distinct from null', 'date_facture', 0),
|
|
|
(1, 'CTI_DTFAC_DTSOR', 2, '', '', 0),
|
|
|
(1, 'CTI_DTFAC_DTSOR', 3, '', '', 0),
|
|
|
(1, 'CTI_DTVEN_DTFAC', 1, 'date_vente < date_facture', 'date_vente, date_facture', 2),
|
|
|
(1, 'CTI_DTVEN_DTFAC', 2, '', '', 0),
|
|
|
(1, 'CTI_DTVEN_DTFAC', 3, '', '', 0),
|
|
|
(1, 'CTI_DUR_SUP_60', 1, 'type_t2a <> 2 and type_t2a <> 3 and duree>60', '', 2),
|
|
|
(1, 'CTI_DUR_SUP_60', 2, '', '', 0),
|
|
|
(1, 'CTI_DUR_SUP_60', 3, '', '', 0),
|
|
|
(1, 'CTI_EXT_DE_X_DS', 1, 'nb_externes = 1
|
|
|
AND date != date_sortie
|
|
|
AND mode_traitement_code = ''07''', '', 1),
|
|
|
(1, 'CTI_EXT_DE_X_DS', 2, '', '', 0),
|
|
|
(1, 'CTI_EXT_DE_X_DS', 3, '', '', 0),
|
|
|
(1, 'CTI_LPP_INC_80', 1, 'DROP TABLE IF EXISTS w_res;
|
|
|
CREATE TEMP TABLE w_res AS
|
|
|
SELECT v_sejours_1.sejour_id
|
|
|
,v_sejours_1.no_sejour
|
|
|
,v_sejours_1.date_sortie
|
|
|
,type_sejour
|
|
|
,code_prevu
|
|
|
,v_factures_lignes_c_1.montant_facture
|
|
|
,array_to_string(array_agg(DISTINCT t_lpp.code),'','') AS lpp_codes
|
|
|
,sum(sortie_montant - entree_montant) AS sortie_montant
|
|
|
,round(100*base.cti_division(sum(sortie_montant - entree_montant), v_factures_lignes_c_1.montant_facture),2) AS rapport
|
|
|
FROM eco.p_sejours
|
|
|
JOIN eco.p_mouvements_articles ON mouvement_id = p_mouvements_articles.oid
|
|
|
JOIN activite.v_sejours_1 ON p_sejours.sejour_id = v_sejours_1.sejour_id
|
|
|
LEFT JOIN base.t_finess ON v_sejours_1.finess = t_finess.code
|
|
|
JOIN eco.t_lpp_c ON lpp_id = t_lpp_c.oid
|
|
|
JOIN base.t_lpp ON t_lpp_c.code = t_lpp.code
|
|
|
JOIN (SELECT no_sejour
|
|
|
,sum(montant_facture) AS montant_facture
|
|
|
FROM activite.v_factures_lignes_c_1
|
|
|
WHERE prestation_code = ''GHS''
|
|
|
GROUP BY 1
|
|
|
) v_factures_lignes_c_1 ON v_factures_lignes_c_1.no_sejour = p_sejours.no_sejour
|
|
|
LEFT JOIN (SELECT no_sejour
|
|
|
,lpp_id
|
|
|
,rubrique_facturation_id
|
|
|
,sum(montant_facture) AS montant_facture
|
|
|
FROM activite.v_factures_lignes_c_5
|
|
|
GROUP BY 1,2,3
|
|
|
) v_factures_lignes_c_5 ON p_sejours.no_sejour = v_factures_lignes_c_5.no_sejour
|
|
|
AND (
|
|
|
rubrique_facturation_id IN (
|
|
|
SELECT to_id
|
|
|
FROM activite.t_listes
|
|
|
LEFT JOIN activite.t_listes_contenu ON liste_id = t_listes.oid
|
|
|
WHERE t_listes.code = ''CTI_PROTHESE_R''
|
|
|
)
|
|
|
OR t_lpp_c.oid = v_factures_lignes_c_5.lpp_id
|
|
|
)
|
|
|
WHERE p_mouvements_articles.lpp_id != 0
|
|
|
AND type_mouvement_id IN (
|
|
|
SELECT to_id
|
|
|
FROM eco.t_classes
|
|
|
JOIN eco.t_classes_sections ON classe_id = t_classes.oid
|
|
|
JOIN eco.t_classes_sections_elements ON section_id = t_classes_sections.oid
|
|
|
WHERE t_classes.code = ''CTI_TYPMVT''
|
|
|
AND t_classes_sections.code = ''01''
|
|
|
)
|
|
|
AND sortie_montant != 0
|
|
|
AND v_factures_lignes_c_1.montant_facture > 0
|
|
|
AND v_factures_lignes_c_5.montant_facture IS NULL
|
|
|
GROUP BY 1,2,3,4,5,6
|
|
|
HAVING base.cti_division(sum(sortie_montant), v_factures_lignes_c_1.montant_facture) > 0.8;
|
|
|
|
|
|
SELECT sejour_id, no_sejour, date_sortie, lpp_codes, montant_facture, sortie_montant, rapport
|
|
|
FROM w_res
|
|
|
WHERE 1 = 1', 'montant_facture, sortie_montant, rapport', 99),
|
|
|
(1, 'CTI_LPP_INC_80', 2, '', '', 0),
|
|
|
(1, 'CTI_LPP_INC_80', 3, '', '', 0),
|
|
|
(1, 'CTI_LPP_NON_FAC', 1, 'SELECT
|
|
|
v_sejours_1.sejour_id,
|
|
|
v_sejours_1.no_sejour,
|
|
|
v_sejours_1.date_sortie,
|
|
|
t_lpp.code as lpp_code,
|
|
|
t_lpp_sus.date_debut as date_debut_lpp,
|
|
|
t_lpp_sus.date_fin as date_fin_lpp,
|
|
|
sortie_montant-entree_montant AS sortie_montant,
|
|
|
montant_facture
|
|
|
FROM
|
|
|
eco.p_sejours
|
|
|
JOIN eco.p_mouvements_articles ON mouvement_id = p_mouvements_articles.oid
|
|
|
JOIN activite.v_sejours_1 ON p_sejours.sejour_id = v_sejours_1.sejour_id
|
|
|
JOIN base.t_finess ON v_sejours_1.finess = t_finess.code
|
|
|
JOIN eco.t_lpp_c on lpp_id = t_lpp_c.oid
|
|
|
JOIN pmsi.t_lpp on t_lpp.code = t_lpp_c.code
|
|
|
LEFT JOIN base.t_lpp_sus on t_lpp_sus.lpp_id = t_lpp_c.oid AND date BETWEEN t_lpp_sus.date_debut AND t_lpp_sus.date_fin
|
|
|
LEFT JOIN activite.v_factures_lignes_c_5 on p_sejours.no_sejour = v_factures_lignes_c_5.no_sejour AND (rubrique_facturation_id IN (
|
|
|
SELECT to_id FROM activite.t_listes LEFT JOIN activite.t_listes_contenu ON liste_id = t_listes.oid WHERE t_listes.code = ''CTI_PROTHESE_R'')
|
|
|
OR v_factures_lignes_c_5.lpp_id = t_lpp_c.oid)
|
|
|
WHERE p_mouvements_articles.lpp_id != 0
|
|
|
AND type_mouvement_id IN (SELECT to_id FROM eco.t_classes JOIN eco.t_classes_sections ON classe_id = t_classes.oid
|
|
|
JOIN eco.t_classes_sections_elements ON section_id = t_classes_sections.oid WHERE t_classes.code = ''CTI_TYPMVT'' and t_classes_sections.code = ''01'')
|
|
|
AND t_lpp_sus.date_debut IS NOT NULL
|
|
|
AND (sortie_montant-entree_montant) > 0
|
|
|
AND v_factures_lignes_c_5.montant_facture IS NULL
|
|
|
AND v_sejours_1.type_sejour = ''1''', 'lpp_code, date_debut_lpp, date_fin_lpp, sortie_montant', 99),
|
|
|
(1, 'CTI_LPP_NON_FAC', 2, '', '', 0),
|
|
|
(1, 'CTI_LPP_NON_FAC', 3, '', '', 0),
|
|
|
(1, 'CTI_MULTI_TYPES', 1, 'SELECT
|
|
|
v_sejours_1.sejour_id,
|
|
|
v_sejours_1.no_sejour,
|
|
|
v_sejours_1.date_sortie,
|
|
|
nb_ambulatoires,
|
|
|
nb_entrees_directes,
|
|
|
nb_seances,
|
|
|
nb_externes
|
|
|
FROM
|
|
|
activite.v_mouvements_sejour_2
|
|
|
JOIN activite.v_sejours_1 using (no_sejour)
|
|
|
WHERE
|
|
|
nb_ambulatoires + nb_entrees_directes + nb_seances + nb_externes > 1', 'nb_ambulatoires, nb_entrees_directes, nb_seances, nb_externes', 99),
|
|
|
(1, 'CTI_MULTI_TYPES', 2, '', '', 0),
|
|
|
(1, 'CTI_MULTI_TYPES', 3, '', '', 0),
|
|
|
(1, 'CTI_MVT_ETA_KO', 1, 'lieu_etage_id IN [LI:CTI_ETA_KO]', 'lieu_etage_code', 1),
|
|
|
(1, 'CTI_MVT_ETA_KO', 2, '', '', 0),
|
|
|
(1, 'CTI_MVT_ETA_KO', 3, '', '', 0),
|
|
|
(1, 'CTI_MVT_ETA_NULL', 1, 'lieu_etage_id = 0 OR lieu_etage_id is null', '', 1),
|
|
|
(1, 'CTI_MVT_ETA_NULL', 2, '', '', 0),
|
|
|
(1, 'CTI_MVT_ETA_NULL', 3, '', '', 0),
|
|
|
(1, 'CTI_MVT_SER_EXT', 1, 'lieu_service_code = ''FSEH_04'' OR lieu_service_code = ''SEUR_04''', 'lieu_service_code', 1),
|
|
|
(1, 'CTI_MVT_SER_EXT', 2, '', '', 0),
|
|
|
(1, 'CTI_MVT_SER_EXT', 3, '', '', 0),
|
|
|
(1, 'CTI_MVT_SER_KO', 1, 'lieu_service_id IN [LI:CTI_SER_KO]', 'lieu_service_code', 1),
|
|
|
(1, 'CTI_MVT_SER_KO', 2, '', '', 0),
|
|
|
(1, 'CTI_MVT_SER_KO', 3, '', '', 0),
|
|
|
(1, 'CTI_MVT_SER_NULL', 1, 'lieu_service_id = 0 OR lieu_service_id is null', '', 1),
|
|
|
(1, 'CTI_MVT_SER_NULL', 2, '', '', 0),
|
|
|
(1, 'CTI_MVT_SER_NULL', 3, '', '', 0),
|
|
|
(1, 'CTI_PRE_SUP_30', 1, 'SELECT v_sejours_1.sejour_id,
|
|
|
v_sejours_1.no_sejour,
|
|
|
v_sejours_1.date_sortie,
|
|
|
v_sejours_1.date_entree,
|
|
|
v_sejours_1.code_sorti
|
|
|
FROM activite.v_sejours_1
|
|
|
WHERE ((select valeur_date from activite.t_divers where code=''NOW'')- v_sejours_1.date_entree) >30
|
|
|
AND v_sejours_1.code_sorti<>''1''
AND v_sejours_1.type_sejour <> ''9'' ', '', 99),
(1, 'CTI_PRE_SUP_30', 2, '', '', 0),
(1, 'CTI_PRE_SUP_30', 3, '', '', 0),
(1, 'CTI_SEJSMR_SUPP90', 1, 'SELECT
v_sejours_1.sejour_id,
v_sejours_1.no_sejour,
v_sejours_1.date_sortie,
v_sejours_1.date_entree,
v_sejours_1.code_sorti
FROM
activite.v_sejours_1
JOIN activite.t_lieux_c on lieu_sortie_id = t_lieux_c.oid
WHERE
date(now()) - v_sejours_1.date_entree > 90
AND v_sejours_1.code_sorti <> ''1''
AND v_sejours_1.type_sejour <> ''9''
AND t_lieux_c.type_t2a = ''2''
AND v_sejours_1.mode_traitement_code <> ''04''
AND NOT EXISTS (
SELECT
v_sejours_1.no_sejour
FROM
activite.p_factures
WHERE
code_facture = ''1''
AND v_sejours_1.no_sejour = p_factures.no_sejour
)
', '', 99),
(1, 'CTI_SEJSMR_SUPP90', 2, '', '', 0),
(1, 'CTI_SEJSMR_SUPP90', 3, '', '', 0),
(1, 'CTI_SEJ_AMB_03', 1, 'mode_traitement_code = ''03''
AND lieu_reference_unite_fonctionnelle_id IN [LI:CTI_UF_AMBU]
AND nb_ambulatoires = 1', 'lieu_reference_service_code', 1),
(1, 'CTI_SEJ_AMB_03', 2, '', '', 0),
(1, 'CTI_SEJ_AMB_03', 3, '', '', 0),
(1, 'CTI_SEJ_DUR_30', 1, 'duree > 30', 'duree', 0),
(1, 'CTI_SEJ_DUR_30', 2, '', '', 0),
(1, 'CTI_SEJ_DUR_30', 3, '', '', 0),
(1, 'CTI_SEJ_DUR_NEG', 1, 'date_sortie < date_entree', 'duree', 0),
(1, 'CTI_SEJ_DUR_NEG', 2, '', '', 0),
(1, 'CTI_SEJ_DUR_NEG', 3, '', '', 0),
(1, 'CTI_SEJ_MED_KO', 1, 'medecin_adm_sejour_id IN [LI:CTI_MED_KO]', 'medecin_adm_sejour_code', 0),
(1, 'CTI_SEJ_MED_KO', 2, '', '', 0),
(1, 'CTI_SEJ_MED_KO', 3, '', '', 0),
(1, 'CTI_SEJ_MED_NULL', 1, '((medecin_adm_sejour_id = 0 OR medecin_adm_sejour_id is null)AND (type_sejour<>9))', '', 0),
(1, 'CTI_SEJ_MED_NULL', 2, '', '', 0),
(1, 'CTI_SEJ_MED_NULL', 3, '', '', 0),
(1, 'CTI_SEJ_SER_FINESS', 1, 'SELECT
v_sejours_1.sejour_id,
v_sejours_1.no_sejour,
v_sejours_1.date_sortie,
service_facturation_code
FROM
activite.v_sejours_1
JOIN
(
SELECT t_services_facturation.oid, t_services_facturation.code as service_facturation_code, t_finess.code AS finess_code
FROM activite.t_services_facturation
LEFT JOIN base.t_finess on t_finess.oid = t_services_facturation.finess_id
) subview ON subview.oid = v_sejours_1.lieu_sortie_service_id
WHERE
subview.finess_code is null', 'service_facturation_code', 99),
(1, 'CTI_SEJ_SER_FINESS', 2, '', '', 0),
(1, 'CTI_SEJ_SER_FINESS', 3, '', '', 0),
(1, 'CTI_UCD_INC_80', 1, 'DROP TABLE IF EXISTS w_res;
CREATE TEMP TABLE w_res AS
SELECT v_sejours_1.sejour_id
,v_sejours_1.no_sejour
,v_sejours_1.date_sortie
,type_sejour
,code_prevu
,v_factures_lignes_c_1.montant_facture
,array_to_string(array_agg(DISTINCT t_ucd.code),'','') AS ucd_codes
,sum(sortie_montant - entree_montant) AS sortie_montant
,round(100*base.cti_division(sum(sortie_montant - entree_montant), v_factures_lignes_c_1.montant_facture),2) AS rapport
FROM eco.p_sejours
JOIN eco.p_mouvements_articles ON mouvement_id = p_mouvements_articles.oid
JOIN activite.v_sejours_1 ON p_sejours.sejour_id = v_sejours_1.sejour_id
LEFT JOIN base.t_finess ON v_sejours_1.finess = t_finess.code
JOIN eco.t_ucd_c ON ucd_id = t_ucd_c.oid
JOIN pmsi.t_ucd ON t_ucd_c.code = t_ucd.code
LEFT JOIN pmsi.t_prestations ON t_ucd.prestation_defaut_id = t_prestations.oid
LEFT JOIN pmsi.t_ucd_tarifs ON t_ucd_tarifs.ucd_id = t_ucd.oid
AND DATE BETWEEN t_ucd_tarifs.date_debut
AND LEAST(t_ucd_tarifs.date_fin, top_taa_date_fin)
JOIN (
SELECT no_sejour
,sum(montant_facture) AS montant_facture
FROM activite.v_factures_lignes_c_1
WHERE prestation_code = ''GHS''
GROUP BY 1
) v_factures_lignes_c_1 ON v_factures_lignes_c_1.no_sejour = p_sejours.no_sejour
LEFT JOIN (
SELECT no_sejour
,ucd_id
,rubrique_facturation_id
,sum(montant_facture) AS montant_facture
FROM activite.v_factures_lignes_c_5
GROUP BY 1,2,3
) v_factures_lignes_c_5 ON p_sejours.no_sejour = v_factures_lignes_c_5.no_sejour
AND (
rubrique_facturation_id IN (
SELECT to_id
FROM activite.t_listes
LEFT JOIN activite.t_listes_contenu ON liste_id = t_listes.oid
WHERE t_listes.code = ''CTI_UCD_R''
)
OR t_ucd_c.oid = v_factures_lignes_c_5.ucd_id
)
WHERE p_mouvements_articles.ucd_id != 0
AND type_mouvement_id IN (
SELECT to_id
FROM eco.t_classes
JOIN eco.t_classes_sections ON classe_id = t_classes.oid
JOIN eco.t_classes_sections_elements ON section_id = t_classes_sections.oid
WHERE t_classes.code = ''CTI_TYPMVT''
AND t_classes_sections.code = ''01''
)
AND (sortie_montant - entree_montant) != 0
AND v_factures_lignes_c_1.montant_facture > 0
AND v_factures_lignes_c_5.montant_facture IS NULL
GROUP BY 1,2,3,4,5,6
HAVING base.cti_division(sum(sortie_montant), v_factures_lignes_c_1.montant_facture) > 0.8;
SELECT sejour_id, no_sejour, date_sortie,ucd_codes, montant_facture, sortie_montant, rapport
FROM w_res
WHERE 1 = 1', 'ucd_codes, montant_facture, sortie_montant, rapport', 99),
(1, 'CTI_UCD_INC_80', 2, '', '', 0),
(1, 'CTI_UCD_INC_80', 3, '', '', 0),
(1, 'CTI_UCD_NON_FACT', 1, 'SELECT
v_sejours_1.sejour_id,
v_sejours_1.no_sejour,
v_sejours_1.date_sortie,
t_ucd.code AS ucd_code,
t_ucd_tarifs.date_debut AS date_debut_ucd,
t_ucd_tarifs.date_fin AS date_fin_ucd,
sortie_montant-entree_montant AS sortie_montant
FROM eco.p_sejours
JOIN eco.p_mouvements_articles ON mouvement_id = p_mouvements_articles.oid
JOIN activite.v_sejours_1 ON p_sejours.sejour_id = v_sejours_1.sejour_id
JOIN eco.t_ucd_c on ucd_id = t_ucd_c.oid
JOIN pmsi.t_ucd on t_ucd_c.code = t_ucd.code
JOIN pmsi.t_ucd_tarifs on t_ucd_tarifs.ucd_id = t_ucd.oid AND date BETWEEN t_ucd_tarifs.date_debut AND LEAST(t_ucd_tarifs.date_fin,top_taa_date_fin)
LEFT JOIN activite.v_factures_lignes_c_5 on p_sejours.sejour_id = v_factures_lignes_c_5.sejour_id
AND (rubrique_facturation_id IN (SELECT to_id FROM activite.t_listes JOIN activite.t_listes_contenu ON t_listes.oid = liste_id WHERE t_listes.code = ''CTI_UCD_R'')
OR v_factures_lignes_c_5.lpp_id = t_ucd_c.oid)
WHERE p_mouvements_articles.ucd_id != 0 AND
sortie_montant != 0
AND v_sejours_1.type_sejour = ''1''
AND v_factures_lignes_c_5.montant_facture is null', 'ucd_code, date_debut_ucd, date_fin_ucd, sortie_montant', 99),
(1, 'CTI_UCD_NON_FACT', 2, '', '', 0),
(1, 'CTI_UCD_NON_FACT', 3, '', '', 0),
(1, 'CTI_VAL_SUP_20K', 1, 'montant_encours>20000', '', 2),
(1, 'CTI_VAL_SUP_20K', 2, '', '', 0),
(1, 'CTI_VAL_SUP_20K', 3, '', '', 0)
;
-- 3/3 : Màj de la table iCTI
UPDATE activite.t_expert_controle_rule
SET numero = 1
WHERE numero IS NULL or NUMERO NOT IN (1,2,3);
UPDATE activite.t_expert_controle_rule
SET
sqlcmd_where = w_dbsetup.sqlcmd_where,
sqlcmd_justificatif = w_dbsetup.sqlcmd_justificatif,
table_id = w_dbsetup.tab
FROM w_dbsetup
JOIN activite.t_expert_controle ON t_expert_controle.code = w_dbsetup.controle_code
WHERE t_expert_controle_rule.controle_id = t_expert_controle.oid AND
t_expert_controle_rule.numero = w_dbsetup.numero AND
(
t_expert_controle_rule.sqlcmd_where IS DISTINCT FROM w_dbsetup.sqlcmd_where OR
t_expert_controle_rule.table_id IS DISTINCT FROM w_dbsetup.tab OR
t_expert_controle_rule.sqlcmd_justificatif IS DISTINCT FROM w_dbsetup.sqlcmd_justificatif
);
INSERT INTO activite.t_expert_controle_rule (
controle_id,
numero,
sqlcmd_where,
sqlcmd_justificatif,
table_id
)
SELECT
t_expert_controle.oid,
w_dbsetup.numero,
w_dbsetup.sqlcmd_where,
w_dbsetup.sqlcmd_justificatif,
w_dbsetup.tab
FROM w_dbsetup
JOIN activite.t_expert_controle ON t_expert_controle.code = w_dbsetup.controle_code
LEFT JOIN activite.t_expert_controle_rule ON
t_expert_controle_rule.controle_id = t_expert_controle.oid AND
t_expert_controle_rule.numero = w_dbsetup.numero
WHERE t_expert_controle_rule.oid IS NULL;
|