0 AND substr(md5(qualif), 1, 8) NOT IN (SELECT code_original FROM rh.t_qualifications) GROUP BY 1,2,3,4 ; -- Màj des rubriques INSERT INTO rh.t_rubriques(code, texte, texte_court, code_original, rang_edition) SELECT code_rub, lib_rub, substr(lib_rub, 1, 50), seq_rub, rank() OVER (ORDER BY code_rub) FROM prod_qsp.rubriques WHERE 1=1 AND seq_rub NOT IN (SELECT code_original FROM rh.t_rubriques) GROUP BY 1,2,3,4 ; -- création des rubriques CTI de cumul INSERT INTO rh.t_rubriques(code, texte, texte_court, code_original, rang_edition) SELECT 'C000', 'Ecart cumulé', 'Ecart cumulé', 'C000', -1 WHERE 'C000' NOT IN (SELECT code_original FROM rh.t_rubriques) ; -- Màj des situations de famille INSERT INTO rh.t_situations_famille(code, texte, texte_court, code_original) SELECT situation_fam, situation_fam, substr(situation_fam,1,50), situation_fam FROM prod_qsp.salaries WHERE 1=1 AND situation_fam NOT IN (SELECT code_original FROM rh.t_situations_famille) GROUP BY 1,2,3,4 ; -- Màj des types de contrat INSERT INTO rh.t_types_contrat(code, texte, texte_court, code_original) SELECT type_contr, lib_contr, substr(lib_contr,1,50), type_contr FROM prod_qsp.types_contr WHERE 1=1 AND type_contr NOT IN (SELECT code_original FROM rh.t_types_contrat) GROUP BY 1,2,3,4 ; -- Màj des statuts INSERT INTO rh.t_statuts(code_original, code, texte, texte_court) SELECT histo_emp.seq_statut||lpad(code_statut_conv, 2, ' '), histo_emp.seq_statut||lpad(code_statut_conv, 2, ' '), lib_statut||' '||code_statut_conv, substr(lib_statut||' '||code_statut_conv, 1, 50) FROM prod_qsp.histo_emp LEFT JOIN prod_qsp.statuts ON statuts.seq_statut = histo_emp.seq_statut WHERE 1=1 AND histo_emp.seq_statut||lpad(code_statut_conv, 2, ' ') NOT IN (SELECT code_original FROM rh.t_statuts) GROUP BY 1,2,3,4 ; -- Màj des types de temps de travail INSERT INTO rh.t_types_temps_travail(code_original, code, texte, texte_court) SELECT CASE WHEN heures_contr IN (151.67, 169, 0) THEN 'TC' ELSE 'TP'||trim(to_char(heures_contr, '000.00')) END, CASE WHEN heures_contr IN (151.67, 169, 0) THEN 'TC' ELSE 'TP'||trim(to_char(heures_contr, '000.00')) END, CASE WHEN heures_contr IN (151.67, 169, 0) THEN 'Temps complet' ELSE 'Temps partiel '||replace(round(heures_contr / 151.67 * 100, 2), '.', ',')||' %' END, CASE WHEN heures_contr IN (151.67, 169, 0) THEN 'Temps complet' ELSE 'Temps partiel '||replace(round(heures_contr / 151.67 * 100, 2), '.', ',')||' %' END FROM prod_qsp.histo_emp WHERE 1=1 AND CASE WHEN heures_contr IN (151.67, 169, 0) THEN 'TC' ELSE 'TP'||trim(to_char(heures_contr, '000.00')) END NOT IN (SELECT code_original FROM rh.t_types_temps_travail) GROUP BY 1,2,3,4 ; -- @TODO Màj des types d'horaire -- Màj des services INSERT INTO rh.t_services(code_original, code, texte, texte_court) SELECT seq_service, code_service, nom_service, substr(nom_service, 1, 50) FROM prod_qsp.services WHERE 1=1 AND seq_service NOT IN (SELECT code_original FROM rh.t_services) GROUP BY 1,2,3,4 ; -- Màj des spécialités INSERT INTO rh.t_specialites(code_original, code, texte, texte_court) SELECT seq_nature, code_nature, lib_nature, substr(lib_nature, 1, 50) FROM prod_qsp.natures_emp WHERE 1=1 AND seq_nature NOT IN (SELECT code_original FROM rh.t_specialites) GROUP BY 1,2,3,4 ; -- Màj des codes emploi INSERT INTO rh.t_codes_emploi(code_original, code, texte, texte_court) SELECT seq_categorie, seq_categorie, lib_categorie, substr(lib_categorie, 1, 50) FROM prod_qsp.categories WHERE 1=1 AND seq_categorie NOT IN (SELECT code_original FROM rh.t_codes_emploi) GROUP BY 1,2,3,4 ; -- @TODO Màj des sociétés d'interim -- Màj des grilles INSERT INTO rh.t_grilles(code_original, code, texte, texte_court) SELECT lpad(num_echelon, 4, '0') || lpad(chevron, 2, '0') || lpad(val_coef, 4, '0'), lpad(num_echelon, 4, '0') || lpad(chevron, 2, '0') || lpad(val_coef, 4, '0'), 'Echelon : '||num_echelon||' - Niveau : '||chevron||' - Coefficient : '||val_coef, 'Ech '||num_echelon||' Niv '||chevron||' Coef '||val_coef FROM prod_qsp.val_echelon WHERE 1=1 AND lpad(num_echelon, 4, '0') || lpad(chevron, 2, '0') || lpad(val_coef, 4, '0') NOT IN (SELECT code_original FROM rh.t_grilles) GROUP BY 1,2,3,4 ; -- Màj des groupes de grilles INSERT INTO rh.t_grilles_groupes(code_original, code, texte, texte_court) SELECT code_groupe, code_groupe, code_groupe, substr(code_groupe, 1, 50) FROM prod_qsp.groupes WHERE 1=1 AND code_groupe NOT IN (SELECT code_original FROM rh.t_grilles_groupes) GROUP BY 1 ; -- Màj des comptes INSERT INTO rh.t_compte(code_original, code, texte, texte_court) SELECT rad_cpt_compta_sal, rad_cpt_compta_sal, rad_cpt_compta_sal, rad_cpt_compta_sal FROM prod_qsp.rubriques WHERE 1=1 AND rad_cpt_compta_sal NOT IN (SELECT code_original FROM rh.t_compte) GROUP BY 1 UNION SELECT rad_cpt_compta_pat, rad_cpt_compta_pat, rad_cpt_compta_pat, rad_cpt_compta_pat FROM prod_qsp.rubriques WHERE 1=1 AND rad_cpt_compta_pat NOT IN (SELECT code_original FROM rh.t_compte) GROUP BY 1 ; -- Màj des motifs d'arret INSERT INTO rh.t_motifs_arret(code_original, code, texte, texte_court) SELECT seq_nat_abs, lib_c_abs, nature_abs, substr(nature_abs, 1, 50) FROM prod_qsp.natures_absence WHERE 1=1 AND seq_nat_abs NOT IN (SELECT code_original FROM rh.t_motifs_arret) GROUP BY 1,2,3,4 ; -- @TODO Màj des précisions du motif d'arrêt -- @TODO Màj des motifs de visite médicale -- @TODO Màj des circonstances d'accident du travail -- @TODO Màj des lieux d'accident du travail -- @TODO Màj de la nature de l'accident du travail -- @TODO Màj des sièges d'accident du travail -- @TODO Màj des listes de formations -- Màj des sections analytiques compta : prévu mais pas alimenté. -- Màj des sections analytiques paie : prévu mais pas alimenté. DROP TABLE IF EXISTS temp.x_ref_rubrique ; CREATE TABLE temp.x_ref_rubrique AS with rub_det_0 as ( select histo_lignes_bul.code_rub as code, histo_lignes_bul.seq_rub as code_original, histo_lignes_bul.code_rub between '100' and '499' as brut, false as hresp, false as hresw, false as odns, false as odnp, histo_lignes_bul.code_rub between '501' and '900' as cosd, histo_lignes_bul.code_rub between '501' and '900' as copa, max(lib_rub) as texte from prod_qsp.histo_lignes_bul where 1=1 -- and histo_lignes_bul.code_rub not in ('100', '387', '627 A', '627 Z', '699', '700', '896', '899', '900') -- and histo_lignes_bul.code_rub not in ('898', '147') -- Spécifique Arago (= icti_344). group by 1,2,3,4,5,6,7,8,9 ) , rub_det_1 as ( select code, code_original, texte, bool_or(brut) or bool_or(odns) or bool_or(odnp) or bool_or(cosd) or bool_or(copa) AS p_detail, false AS p_nombre, bool_or(brut) or bool_or(odns) or bool_or(odnp) or bool_or(cosd) or bool_or(copa) AS p_base, bool_or(hresp) AS p_heures_payees, bool_or(hresw) AS p_heures_travaillees, bool_or(brut) or bool_or(odnp) or bool_or(copa) AS p_masse_salariale, bool_or(brut) AS p_brut, false AS p_avantage_nature, false AS p_frais_imposables, bool_or(cosd) AS p_cotisation_salarie, bool_or(copa) AS p_cotisation_patronale, bool_or(odns) AS p_od_net_salarie, false AS p_od_net_patronale, bool_or(brut) or bool_or(cosd) AS p_net_imposable, -- case when bool_or(cosd) then 1 else -1 end as c_net_imposable, bool_or(brut) or bool_or(cosd) or bool_or(odns) AS p_net_a_payer -- case when bool_or(cosd) then 1 else -1 end as c_net_a_payer from rub_det_0 group by 1,2,3 ) SELECT code_original, code, texte, null::text as texte_court, -1 as rang_edition, false as p_cumul, p_detail as p_detail, p_nombre as p_nombre, 0 as s_nombre, 1 as c_nombre, p_base as p_base, 1 as s_base, 1 as c_base, false as p_heures_contrat, 0 as s_heures_contrat, 1 as c_heures_contrat, p_heures_payees as p_heures_payees, 0 as s_heures_payees, 1 as c_heures_payees, p_heures_travaillees as p_heures_travaillees, 0 as s_heures_travaillees, 1 as c_heures_travaillees, p_masse_salariale as p_masse_salariale, case when p_cotisation_patronale or p_od_net_patronale then 5 else 3 end as s_masse_salariale, case when p_cotisation_patronale then -1 else 1 end as c_masse_salariale, p_brut as p_brut, 3 as s_brut, 1 as c_brut, p_avantage_nature as p_avantage_nature, 3 as s_avantage_nature, 1 as c_avantage_nature, p_frais_imposables as p_frais_imposables, 3 as s_frais_imposables, 1 as c_frais_imposables, p_cotisation_salarie as p_cotisation_salarie, 3 as s_cotisation_salarie, 1 as c_cotisation_salarie, p_cotisation_patronale as p_cotisation_patronale, 5 as s_cotisation_patronale, -1 as c_cotisation_patronale, p_od_net_salarie as p_od_net_salarie, 3 as s_od_net_salarie, 1 as c_od_net_salarie, p_od_net_patronale as p_od_net_patronale, 5 as s_od_net_patronale, 1 as c_od_net_patronale, p_net_imposable as p_net_imposable, 3 as s_net_imposable, 1 as c_net_imposable, p_net_a_payer as p_net_a_payer, 3 as s_net_a_payer, 1 as c_net_a_payer FROM rub_det_1 ; -- Pré-paramétrage automatique des rubriques (au mieux). -- Cette requête n'intervient pas sur les rubriques paramétrées à la main. update rh.t_rubriques set p_cumul = x_ref_rubrique.p_cumul, p_detail = x_ref_rubrique.p_detail, p_nombre = x_ref_rubrique.p_nombre, s_nombre = x_ref_rubrique.s_nombre, c_nombre = x_ref_rubrique.c_nombre, p_base = x_ref_rubrique.p_base, s_base = x_ref_rubrique.s_base, c_base = x_ref_rubrique.c_base, p_heures_contrat = x_ref_rubrique.p_heures_contrat, s_heures_contrat = x_ref_rubrique.s_heures_contrat, c_heures_contrat = x_ref_rubrique.c_heures_contrat, p_heures_payees = x_ref_rubrique.p_heures_payees, s_heures_payees = x_ref_rubrique.s_heures_payees, c_heures_payees = x_ref_rubrique.c_heures_payees, p_heures_travaillees = x_ref_rubrique.p_heures_travaillees, s_heures_travaillees = x_ref_rubrique.s_heures_travaillees, c_heures_travaillees = x_ref_rubrique.c_heures_travaillees, p_masse_salariale = x_ref_rubrique.p_masse_salariale, s_masse_salariale = x_ref_rubrique.s_masse_salariale, c_masse_salariale = x_ref_rubrique.c_masse_salariale, p_brut = x_ref_rubrique.p_brut, s_brut = x_ref_rubrique.s_brut, c_brut = x_ref_rubrique.c_brut, p_avantage_nature = x_ref_rubrique.p_avantage_nature, s_avantage_nature = x_ref_rubrique.s_avantage_nature, c_avantage_nature = x_ref_rubrique.c_avantage_nature, p_frais_imposables = x_ref_rubrique.p_frais_imposables, s_frais_imposables = x_ref_rubrique.s_frais_imposables, c_frais_imposables = x_ref_rubrique.c_frais_imposables, p_cotisation_salarie = x_ref_rubrique.p_cotisation_salarie, s_cotisation_salarie = x_ref_rubrique.s_cotisation_salarie, c_cotisation_salarie = x_ref_rubrique.c_cotisation_salarie, p_cotisation_patronale = x_ref_rubrique.p_cotisation_patronale, s_cotisation_patronale = x_ref_rubrique.s_cotisation_patronale, c_cotisation_patronale = x_ref_rubrique.c_cotisation_patronale, p_od_net_salarie = x_ref_rubrique.p_od_net_salarie, s_od_net_salarie = x_ref_rubrique.s_od_net_salarie, c_od_net_salarie = x_ref_rubrique.c_od_net_salarie, p_od_net_patronale = x_ref_rubrique.p_od_net_patronale, s_od_net_patronale = x_ref_rubrique.s_od_net_patronale, c_od_net_patronale = x_ref_rubrique.c_od_net_patronale, p_net_imposable = x_ref_rubrique.p_net_imposable, s_net_imposable = x_ref_rubrique.s_net_imposable, c_net_imposable = x_ref_rubrique.c_net_imposable, p_net_a_payer = x_ref_rubrique.p_net_a_payer, s_net_a_payer = x_ref_rubrique.s_net_a_payer, c_net_a_payer = x_ref_rubrique.c_net_a_payer from temp.x_ref_rubrique where 1=1 AND t_rubriques.code_original = x_ref_rubrique.code_original AND NOT t_rubriques.user_modified ; ]]> 0 -- and bulletins.num_bul_annule = 0 -- On prend tous les bulletins, y compris les réguls. AND bulletins.date_paye >= rhp('rhprovider_start')::date ; TRUNCATE rh.p_chiffrier_production ; INSERT INTO rh.p_chiffrier_production (entreprise_id, etablissement_id, mois, nombre_salaries, montant_brut, nombre_heures) select t_entreprises.oid, t_etablissements.oid, mois_paie, count(distinct num_sal), sum(res_sal), sum(base) from w_bulletins AS bulletins join prod_qsp.histo_lignes_bul ON 1=1 AND histo_lignes_bul.seq_emploi = bulletins.seq_emploi AND case when histo_lignes_bul.NUM_BUL > 0 then histo_lignes_bul.NUM_BUL else @(histo_lignes_bul.NUM_BUL + 99999) end = bulletins.NUM_BUL JOIN rh.t_etablissements ON t_etablissements.code_original = 1 -- @todo : code établissement en dur JOIN rh.t_entreprises ON t_entreprises.oid = t_etablissements.entreprise_id WHERE 1=1 AND mois_paie >= 200901 AND histo_lignes_bul.code_rub in ('500') GROUP BY 1,2,3 ; ]]> date_debut_contrat ; UPDATE rh.p_salaries SET date_entree_ets = date_debut_contrat FROM (SELECT salarie_id, min(date_debut) AS date_debut_contrat from rh.p_contrats group by 1) AS s WHERE 1=1 AND p_salaries.oid = s.salarie_id AND to_char(date_entree_ets, 'YYYY')::numeric >= 2009 AND date_entree_ets < date_debut_contrat ; UPDATE rh.p_salaries SET date_sortie_ets = date_fin_contrat FROM (SELECT salarie_id, max(date_fin) AS date_fin_contrat from rh.p_contrats group by 1) AS s WHERE 1=1 AND p_salaries.oid = s.salarie_id AND date_fin_contrat > date_sortie_ets ; -- Calcul ancienneté au début de contrat UPDATE rh.p_contrats SET anciennete_anterieure_jours = subq.anciennete_anterieure_jours, anciennete_anterieure_calculee_mois = subq.anciennete_anterieure_calculee_mois FROM ( SELECT t1.seq_emploi, sum((t2.cti_date_fin - t2.cti_date_debut) + 1) AS anciennete_anterieure_jours, sum((t2.cti_date_fin - t2.cti_date_debut) + 1) / 30 AS anciennete_anterieure_calculee_mois FROM w_emplois AS t1 JOIN w_emplois AS t2 ON 1=1 AND t2.num_sal = t1.num_sal AND t2.cti_date_debut < t1.cti_date_debut group by 1 ) AS subq WHERE 1=1 AND p_contrats.numero_contrat = subq.seq_emploi ; TRUNCATE rh.p_contrats_mois ; ALTER SEQUENCE rh.s_contrats_mois RESTART WITH 1 ; INSERT INTO rh.p_contrats_mois( salarie_id, contrat_id, mois_activite, date_debut, date_fin, nombre_entrees, nombre_departs, nombre_debut_contrat, nombre_fin_contrat, est_hors_periode, present_debut_mois, present_fin_mois, equivalent_temps_plein, age_id, age_jours, anciennete_jours, anciennete_mois, anciennete_annee_id ) SELECT p_salaries.oid AS salarie_id, p_contrats.oid AS contrat_id, w_salarie_mois.mois AS mois, w_salarie_mois.date_debut AS date_debut, w_salarie_mois.date_fin AS date_fin, CASE WHEN p_salaries.date_entree_ets BETWEEN w_salarie_mois.date_debut AND w_salarie_mois.date_fin THEN 1 ELSE 0 END AS nombre_entrees, CASE WHEN p_salaries.date_sortie_ets BETWEEN w_salarie_mois.date_debut AND w_salarie_mois.date_fin THEN 1 ELSE 0 END AS nombre_departs, CASE WHEN p_contrats.date_debut BETWEEN w_salarie_mois.date_debut AND w_salarie_mois.date_fin THEN 1 ELSE 0 END AS nombre_debut_contrat, CASE WHEN p_contrats.date_fin BETWEEN w_salarie_mois.date_debut AND w_salarie_mois.date_fin THEN 1 ELSE 0 END AS nombre_fin_contrat, 0 AS est_hors_periode, CASE WHEN base.cti_first_day(w_salarie_mois.date_debut) BETWEEN p_contrats.date_debut AND p_contrats.date_fin THEN 1 ELSE 0 END AS present_debut_mois, CASE WHEN base.cti_last_day(w_salarie_mois.date_fin) BETWEEN p_contrats.date_debut AND p_contrats.date_fin THEN 1 ELSE 0 END AS present_fin_mois, 0, -- L'ETP théorique est calculé plus loin à l'issue de la "Ventilation des profils". base.cti_age(LEAST(w_salarie_mois.date_fin, w_salarie_mois.date_fin), COALESCE(p_salaries.date_naissance, '1962-04-18'::date), 'ny') AS age_id, LEAST(w_salarie_mois.date_fin, w_salarie_mois.date_fin)::date - COALESCE(p_salaries.date_naissance, '1962-04-18'::date) AS age_jours, p_contrats.anciennete_anterieure_jours + (LEAST(w_salarie_mois.date_fin, w_salarie_mois.date_fin) - p_contrats.date_debut) + 1 AS anciennete_jours, base.cti_months_between(p_contrats.date_debut, w_salarie_mois.date_fin) + p_contrats.anciennete_anterieure_calculee_mois AS anciennete_mois, floor( ( base.cti_months_between(p_contrats.date_debut, w_salarie_mois.date_fin) + p_contrats.anciennete_anterieure_calculee_mois ) / 12 ) AS anciennete_annee_id FROM w_salarie_mois JOIN rh.p_contrats ON p_contrats.numero_contrat = w_salarie_mois.histo_emp_seq_emploi JOIN rh.p_salaries ON p_salaries.matricule = w_salarie_mois.num_sal WHERE 1=1 AND w_salarie_mois.mois < to_char(now() + '1 month'::interval, 'YYYYMM') GROUP BY 1,2,3,4,5,6,7,8,9,10,11,12,13,14,15,16,17 ; ]]> 0 then histo_lignes_bul.NUM_BUL else @(histo_lignes_bul.NUM_BUL + 99999) end = bulletins.NUM_BUL and histo_lignes_bul.num_bul = bulletins.num_bul JOIN prod_qsp.rubriques ON rubriques.seq_rub = histo_lignes_bul.seq_rub JOIN rh.t_rubriques on t_rubriques.code_original = rubriques.seq_rub where false OR t_rubriques.p_detail OR t_rubriques.p_cumul --GROUP BY 1,2,3,4,5,6,7,8 ; DROP TABLE IF EXISTS w_hp ; CREATE TEMP TABLE w_hp AS SELECT w_hp_0.bul_id, p_salaries.oid as salarie_id, date_part('year', age(w_hp_0.date_debut, date_naissance)) AS age_id, w_hp_0.matricule as sal_code_original, w_hp_0.matricule, w_hp_0.date_debut, w_hp_0.date_fin, w_hp_0.mois_paie as mois_activite, w_hp_0.date_fin as date_paie, w_hp_0.mois_paie, rubrique_id, coalesce(t_organismes_cotisation.oid, 0) as organisme_cotisation_id, coalesce(t_compte.oid, 0) as compte_id, base, nombre, heure_contrat, heure_payee, heure_travaillee, montant_masse_salariale, montant_brut, montant_frais_imposables, taux_cotisation_salarie, montant_cotisation_salarie, taux_cotisation_patronale, montant_cotisation_patronale, montant_od_net_salarie, montant_od_net_patronale, montant_avantage_nature, montant_net_imposable_salarie, montant_net_a_payer_salarie, p_cumul, p_detail, (max(ARRAY[EXTRACT(EPOCH FROM p_contrats_mois.date_fin), p_contrats_mois.oid]))[2] AS contrat_mois_id, (max(ARRAY[EXTRACT(EPOCH FROM p_contrats_mois.date_fin), p_contrats_mois.contrat_id]))[2] AS contrat_id, (max(ARRAY[EXTRACT(EPOCH FROM p_contrats_mois.date_fin), p_contrats_mois.etablissement_id]))[2] as etablissement_id, 0::bigint as profil_id FROM w_hp_0 JOIN rh.p_salaries ON p_salaries.matricule = w_hp_0.matricule LEFT JOIN rh.t_organismes_cotisation ON t_organismes_cotisation.code_original = w_hp_0.caisse_code_original LEFT JOIN rh.t_compte ON t_compte.code_original = w_hp_0.compte_code_original LEFT JOIN rh.p_contrats_mois ON 1=1 AND p_contrats_mois.salarie_id = p_salaries.oid AND base.cti_overlaps(p_contrats_mois.date_debut, p_contrats_mois.date_fin, w_hp_0.date_debut, w_hp_0.date_fin) GROUP BY 1,2,3,4,5,6,7,8,9,10,11,12,13,14,15,16,17,18,19,20,21,22,23,24,25,26,27,28,29,30,31,32 ; -- Association avec le contrat précédent. with toto as ( SELECT w_hp.bul_id, (max(array[extract(epoch from w_hp.date_fin), p_contrats_mois.contrat_id]))[2] as contrat_id, (max(array[extract(epoch from w_hp.date_fin), p_contrats_mois.oid]))[2] as contrat_mois_id from w_hp join rh.p_contrats_mois on 1=1 and p_contrats_mois.salarie_id = w_hp.salarie_id and p_contrats_mois.date_fin < w_hp.date_debut where w_hp.contrat_mois_id is null group by 1 ) UPDATE w_hp set contrat_id = toto.contrat_id, contrat_mois_id = toto.contrat_mois_id from toto where w_hp.bul_id = toto.bul_id ; TRUNCATE rh.p_historique_paie ; INSERT INTO rh.p_historique_paie( code_original, etablissement_id, age_id, contrat_id, contrat_mois_id, date_debut, date_fin, mois_activite, date_paie, mois_paie, base, nombre, heure_contrat, heure_payee, heure_travaillee, montant_masse_salariale, montant_brut, montant_avantage_nature, montant_frais_imposables, montant_cotisation_salarie, montant_cotisation_patronale, montant_od_net_salarie, montant_od_net_patronale, montant_net_imposable_salarie, montant_net_a_payer_salarie, taux_cotisation_salarie, taux_cotisation_patronale, organisme_cotisation_id, profil_id, rubrique_id, compte_id, salarie_id) SELECT w_hp.bul_id, w_hp.etablissement_id, w_hp.age_id, w_hp.contrat_id, w_hp.contrat_mois_id, w_hp.date_debut, w_hp.date_fin, w_hp.mois_activite, w_hp.date_paie, w_hp.mois_paie, w_hp.base, w_hp.nombre, w_hp.heure_contrat, w_hp.heure_payee, w_hp.heure_travaillee, w_hp.montant_masse_salariale, w_hp.montant_brut, w_hp.montant_avantage_nature, w_hp.montant_frais_imposables, w_hp.montant_cotisation_salarie, w_hp.montant_cotisation_patronale, w_hp.montant_od_net_salarie, w_hp.montant_od_net_patronale, w_hp.montant_net_imposable_salarie, w_hp.montant_net_a_payer_salarie, w_hp.taux_cotisation_salarie, w_hp.taux_cotisation_patronale, w_hp.organisme_cotisation_id, w_hp.profil_id, w_hp.rubrique_id, w_hp.compte_id, w_hp.salarie_id FROM w_hp where p_detail ; -- Création d'une table récapitulative des écarts à calculer par indicateur de paie (1 seule ligne). DROP TABLE IF EXISTS w_cumul ; CREATE TEMP TABLE w_cumul AS SELECT bool_or(p_cumul and p_heures_contrat) as total_heures_contrat, bool_or(p_cumul and p_heures_payees) as total_heures_payees, bool_or(p_cumul and p_heures_travaillees) as total_heures_travaillees, bool_or(p_cumul and p_masse_salariale) as total_masse_salariale, bool_or(p_cumul and p_brut) as total_brut, bool_or(p_cumul and p_avantage_nature) as total_avantage_nature, bool_or(p_cumul and p_frais_imposables) as total_frais_imposables, bool_or(p_cumul and p_cotisation_salarie) as total_cotisation_salarie, bool_or(p_cumul and p_cotisation_patronale) as total_cotisation_patronale, bool_or(p_cumul and p_od_net_salarie) as total_od_net_salarie, bool_or(p_cumul and p_od_net_patronale) as total_od_net_patronale, bool_or(p_cumul and p_net_imposable) as total_net_imposable, bool_or(p_cumul and p_net_a_payer) as total_net_a_payer FROM rh.t_rubriques ; -- Création d'une table temp qui regroupe tous les totaux à atteindre pour calculer l'écart DROP TABLE IF EXISTS w_totaux ; CREATE TEMP TABLE w_totaux AS SELECT w_hp.bul_id, w_hp.etablissement_id, w_hp.salarie_id, w_hp.mois_paie, sum(case when p_heures_contrat then heure_contrat else 0 end) as heure_contrat, sum(case when p_heures_payees then heure_payee else 0 end) as heure_payee, sum(case when p_heures_travaillees then heure_travaillee else 0 end) as heure_travaillee, sum(case when p_masse_salariale then montant_masse_salariale else 0 end) as montant_masse_salariale, sum(case when p_brut then montant_brut else 0 end) AS montant_brut, sum(case when p_avantage_nature then montant_avantage_nature else 0 end) as montant_avantage_nature, sum(case when p_frais_imposables then montant_frais_imposables else 0 end) as montant_frais_imposables, sum(case when p_cotisation_salarie then montant_cotisation_salarie else 0 end) AS montant_cotisation_salarie, sum(case when p_cotisation_patronale then montant_cotisation_patronale else 0 end) AS montant_cotisation_patronale, sum(case when p_od_net_salarie then montant_od_net_salarie else 0 end) as montant_od_net_salarie, sum(case when p_od_net_patronale then montant_od_net_patronale else 0 end) as montant_od_net_patronale, sum(case when p_net_imposable then montant_net_imposable_salarie else 0 end) as montant_net_imposable_salarie, sum(case when p_net_a_payer then montant_net_a_payer_salarie else 0 end) as montant_net_a_payer_salarie FROM w_hp JOIN rh.t_rubriques ON t_rubriques.oid = w_hp.rubrique_id where w_hp.p_cumul GROUP BY 1,2,3,4 ; -- Insérer pour chaque bulletin une ligne qui va faire le compte avec le total (rubrique 'C000' nommée 'Ecart cumulé') INSERT INTO rh.p_historique_paie ( code_original, etablissement_id, age_id, contrat_id, contrat_mois_id, date_debut, date_fin, date_paie, mois_activite, mois_paie, base, nombre, heure_contrat, heure_payee, heure_travaillee, montant_masse_salariale, montant_brut, montant_avantage_nature, montant_frais_imposables, montant_cotisation_salarie, montant_cotisation_patronale, montant_od_net_salarie, montant_od_net_patronale, montant_net_imposable_salarie, montant_net_a_payer_salarie, organisme_cotisation_id, profil_id, rubrique_id, compte_id, salarie_id, taux_cotisation_patronale, taux_cotisation_salarie) WITH subq as ( SELECT p_historique_paie.code_original as bul_id, p_historique_paie.etablissement_id, p_historique_paie.age_id, p_historique_paie.contrat_id, p_historique_paie.contrat_mois_id, p_historique_paie.date_debut, p_historique_paie.date_fin, p_historique_paie.date_paie, p_historique_paie.mois_activite, p_historique_paie.mois_paie, 0 AS base, 0 AS nombre, 0 AS organisme_cotisation_id, 0 AS profil_id, (SELECT oid FROM rh.t_rubriques WHERE code = 'C000') as rubrique_id, 0 AS compte_id, salarie_id, 0 AS taux_cotisation_patronale, 0 AS taux_cotisation_salarie, sum(heure_contrat) AS heure_contrat, sum(heure_payee) AS heure_payee, sum(heure_travaillee) AS heure_travaillee, sum(montant_masse_salariale) AS montant_masse_salariale, sum(montant_brut) AS montant_brut, sum(montant_avantage_nature) AS montant_avantage_nature, sum(montant_frais_imposables) AS montant_frais_imposables, sum(montant_cotisation_salarie) AS montant_cotisation_salarie, sum(montant_cotisation_patronale) AS montant_cotisation_patronale, sum(montant_od_net_salarie) AS montant_od_net_salarie, sum(montant_od_net_patronale) AS montant_od_net_patronale, sum(montant_net_imposable_salarie) AS montant_net_imposable_salarie, sum(montant_net_a_payer_salarie) AS montant_net_a_payer_salarie FROM rh.p_historique_paie GROUP BY 1,2,3,4,5,6,7,8,9,10,11,12,13,14,15,16,17,18 ) SELECT subq.bul_id, subq.etablissement_id, subq.age_id, subq.contrat_id, subq.contrat_mois_id, subq.date_debut, subq.date_fin, subq.date_paie, subq.mois_activite, subq.mois_paie, subq.base, subq.nombre, case when total_heures_contrat then w_totaux.heure_contrat - subq.heure_contrat else 0 end as heure_contrat, case when total_heures_payees then w_totaux.heure_payee - subq.heure_payee else 0 end as heure_payee, case when total_heures_travaillees then w_totaux.heure_travaillee - subq.heure_travaillee else 0 end as heure_travaillee, case when total_masse_salariale then w_totaux.montant_masse_salariale - subq.montant_masse_salariale else 0 end as montant_masse_salariale, case when total_brut then w_totaux.montant_brut - subq.montant_brut else 0 end as montant_brut, case when total_avantage_nature then w_totaux.montant_avantage_nature - subq.montant_avantage_nature else 0 end as montant_avantage_nature, case when total_frais_imposables then w_totaux.montant_frais_imposables - subq.montant_frais_imposables else 0 end as montant_frais_imposables, case when total_cotisation_salarie then w_totaux.montant_cotisation_salarie - subq.montant_cotisation_salarie else 0 end as montant_cotisation_salarie, case when total_cotisation_patronale then w_totaux.montant_cotisation_patronale - subq.montant_cotisation_patronale else 0 end as montant_cotisation_patronale, case when total_od_net_salarie then w_totaux.montant_od_net_salarie - subq.montant_od_net_salarie else 0 end as montant_od_net_salarie, case when total_od_net_patronale then w_totaux.montant_od_net_patronale - subq.montant_od_net_patronale else 0 end as montant_od_net_patronale, case when total_net_imposable then w_totaux.montant_net_imposable_salarie - subq.montant_net_imposable_salarie else 0 end as montant_net_imposable_salarie, case when total_net_a_payer then w_totaux.montant_net_a_payer_salarie - subq.montant_net_a_payer_salarie else 0 end as montant_net_a_payer_salarie, subq.organisme_cotisation_id AS organisme_cotisation_id, subq.profil_id, subq.rubrique_id, subq.compte_id, subq.salarie_id, subq.taux_cotisation_patronale, subq.taux_cotisation_salarie FROM subq JOIN w_totaux ON w_totaux.bul_id = subq.bul_id JOIN w_cumul ON true WHERE 1!=1 OR (total_heures_contrat AND w_totaux.heure_contrat - subq.heure_contrat != 0) OR (total_heures_payees AND w_totaux.heure_payee - subq.heure_payee != 0) OR (total_heures_travaillees AND w_totaux.heure_travaillee - subq.heure_travaillee != 0) OR (total_masse_salariale AND w_totaux.montant_masse_salariale - subq.montant_masse_salariale != 0) OR (total_brut AND w_totaux.montant_brut - subq.montant_brut != 0) OR (total_avantage_nature AND w_totaux.montant_avantage_nature - subq.montant_avantage_nature != 0) OR (total_frais_imposables AND w_totaux.montant_frais_imposables - subq.montant_frais_imposables != 0) OR (total_cotisation_salarie AND w_totaux.montant_cotisation_salarie - subq.montant_cotisation_salarie != 0) OR (total_cotisation_patronale AND w_totaux.montant_cotisation_patronale - subq.montant_cotisation_patronale != 0) OR (total_od_net_salarie AND w_totaux.montant_od_net_salarie - subq.montant_od_net_salarie != 0) OR (total_od_net_patronale AND w_totaux.montant_od_net_patronale - subq.montant_od_net_patronale != 0) OR (total_net_imposable AND w_totaux.montant_net_imposable_salarie - subq.montant_net_imposable_salarie != 0) OR (total_net_a_payer AND w_totaux.montant_net_a_payer_salarie - subq.montant_net_a_payer_salarie != 0) ; SELECT base.cti_stash_pop_table_indexes('rh', 'p_historique_paie') ; ]]> = p_contrats_mois.date_debut GROUP BY 1,2,3,5,p_arrets_travail.date_debut,p_arrets_travail.date_fin,p_arrets_travail.date_reprise ORDER BY p_contrats_mois.mois_activite desc ; update rh.p_arrets_travail_mois set nb_reprise_apres_arret = subq.nb_reprise_apres_arret from ( select t1.arret_travail_id, t1.mois_activite, min(case when p_arrets_travail.date_reprise between t2.date_debut and t2.date_fin then 0 else 1 end) as nb_reprise_apres_arret from rh.p_arrets_travail_mois as t1 join rh.p_arrets_travail ON p_arrets_travail.oid = t1.arret_travail_id left join rh.p_arrets_travail_mois as t2 ON 1=1 AND t1.salarie_id = t2.salarie_id AND t1.date_debut != t2.date_debut AND t1.date_fin != t2.date_fin GROUP BY t1.arret_travail_id, t1.mois_activite order by 2 desc ) as subq where 1=1 and p_arrets_travail_mois.arret_travail_id = subq.arret_travail_id and p_arrets_travail_mois.mois_activite = subq.mois_activite ; ]]>