trim(code_original) ; UPDATE prod_quadrarh.employes SET NUMERO = trim(NUMERO) WHERE NUMERO <> trim(NUMERO) ; UPDATE prod_quadrarh.bulletins SET NUMEROEMPLOYE = trim(NUMEROEMPLOYE) WHERE NUMEROEMPLOYE <> trim(NUMEROEMPLOYE) ; UPDATE prod_quadrarh.entreesortieemp SET NUMEROEMPLOYE = trim(NUMEROEMPLOYE) WHERE NUMEROEMPLOYE <> trim(NUMEROEMPLOYE) ; UPDATE prod_quadrarh.infoscomplbul SET NUMERO = trim(NUMERO) WHERE NUMERO <> trim(NUMERO) ; UPDATE prod_quadrarh.lignesbulletin SET NUMEROEMPLOYE = trim(NUMEROEMPLOYE) WHERE NUMEROEMPLOYE <> trim(NUMEROEMPLOYE) ; UPDATE prod_quadrarh.infoscomplbul SET CDDCDI = CASE WHEN CDDCDI ILIKE 'True' THEN '1' WHEN CDDCDI ILIKE 'False' THEN '0' ELSE CDDCDI END WHERE CDDCDI ILIKE 'True' OR CDDCDI ILIKE 'False' ; ]]> 0 then 'NET' else 'BRUT' end) else typeabsence end as code_original, max(libelle) as intitule from prod_quadrarh.lignesbulletin group by 1,2) , all_rubs as ( select code, code_original, max(intitule) as intitule from all_rubs_0 group by 1,2) SELECT code_original, code, intitule, substr(intitule, 1, 50), -1 FROM all_rubs WHERE code_original NOT IN (SELECT code_original FROM rh.t_rubriques WHERE code_original IS NOT NULL) GROUP BY 1,2,3,4,5 ; -- -- Màj des situations de famille -- INSERT INTO rh.t_situations_famille(code_original, code, texte, texte_court) -- SELECT situationfamille, situationfamille, substr(situationfamille,1,50), situationfamille -- FROM prod_sage.t_hst_famille -- WHERE situationfamille NOT IN (SELECT code_original FROM rh.t_situations_famille WHERE code_original IS NOT NULL) -- GROUP BY 1,2,3,4 -- ; -- Màj des types de contrat INSERT INTO rh.t_types_contrat(code_original, code, texte, texte_court) SELECT cddcdi, cddcdi, cddcdi, substr(cddcdi, 1, 50) FROM w_hst WHERE cddcdi NOT IN (SELECT code_original FROM rh.t_types_contrat WHERE code_original IS NOT NULL) GROUP BY 1,2,3,4 ; -- Màj des statuts INSERT INTO rh.t_statuts(code_original, code, texte, texte_court) select statut_code, statut_code, MAX(statut_libelle), MAX(substr(statut_libelle, 1, 50)) from w_hst WHERE statut_code NOT IN (SELECT code_original FROM rh.t_statuts WHERE code_original IS NOT NULL) GROUP BY 1,2 ; -- Màj des types de temps de travail INSERT INTO rh.t_types_temps_travail(code_original, code, texte, texte_court) select ttt, ttt, ttt_libelle, ttt_libelle_court from w_hst where ttt NOT IN (SELECT code_original FROM rh.t_types_temps_travail WHERE code_original IS NOT NULL) group by 1,2,3,4 ; -- Màj des services INSERT INTO rh.t_services(code_original, code, texte, texte_court) SELECT code, code, intitule, substr(intitule, 1, 50) FROM prod_quadrarh.services WHERE code NOT IN (SELECT code_original FROM rh.t_services WHERE code_original IS NOT NULL) GROUP BY 1,2,3,4 ; -- Màj des codes emploi. prod_quadrarh.profils ? INSERT INTO rh.t_codes_emploi(code_original, code, texte, texte_court) SELECT emploi_code, emploi_code, emploi_libelle, substr(emploi_libelle, 1, 50) FROM w_hst WHERE emploi_code NOT IN (SELECT code_original FROM rh.t_codes_emploi WHERE code_original IS NOT NULL) 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 classification, classification, classification, substr(classification, 1, 50) from w_hst WHERE classification NOT IN (SELECT code_original FROM rh.t_grilles_groupes WHERE code_original IS NOT NULL) GROUP BY 1,2,3,4 ; ]]> = to_char(rhp('rhprovider_start')::date, 'YYYYMM')::int GROUP BY 1,2,3 ; ]]> base.cti_first_day((w_profils.mois::text||'01')::date) then 0 else (case when w_profils.est_hors_periode = 1 then 0 else 1 end) end as present_debut_mois, case when w_profils.cnt_date_fin < base.cti_last_day((w_profils.mois::text||'01')::date) then 0 else (case when w_profils.est_hors_periode = 1 then 0 else 1 end) end as present_fin_mois, 1 as equivalent_temps_plein, -- ! Mettre le bon ETP. base.cti_age(least(w_profils.date_fin, w_profils.cnt_date_fin)::date, coalesce(p_salaries.date_naissance, '1962-04-18'::date), 'ny') AS age_id, least(w_profils.date_fin, w_profils.cnt_date_fin)::date - coalesce(p_salaries.date_naissance, '1962-04-18'::date) AS age_jours, p_contrats.anciennete_anterieure_jours + (w_profils.date_fin - w_profils.cnt_date_debut) + 1 AS anciennete_jours, base.cti_age(date_trunc('month', w_profils.date_fin::date)::date, date_trunc('month', w_profils.cnt_date_debut)::date, 'nm') + p_contrats.anciennete_anterieure_calculee_mois + 1 AS anciennete_mois, floor((base.cti_age(date_trunc('month', w_profils.date_fin::date)::date, date_trunc('month', w_profils.cnt_date_debut)::date, 'nm') + p_contrats.anciennete_anterieure_calculee_mois + 1) / 12) AS anciennete_annee_id, p_contrats.etablissement_id FROM w_profils JOIN rh.p_contrats on p_contrats.code_original = w_profils.ncnt JOIN rh.p_salaries on p_salaries.oid = p_contrats.salarie_id ; -- On renseigne les id de contrats de w_profils. UPDATE w_profils SET contrat_id = p_contrats_mois.contrat_id, contrat_mois_id = p_contrats_mois.oid FROM rh.p_contrats_mois WHERE w_profils.row_id = p_contrats_mois.code_original ; ]]> 0 then 'NET' else 'BRUT' end) else typeabsence end as code, -- libelle, case when code = '.NAP' then montantglobal::numeric else montant2::numeric end as base, montant1::numeric as nombre, montantsalarial::numeric as tx_sal, coalesce(nullif(round(montant2::numeric * montant1::numeric, 2), 0), round(montant2::numeric * montantsalarial::numeric / 100.0 , 2)) as mt_sal, (montantglobal::numeric - montantsalarial::numeric) as tx_pat, round(montant2::numeric * (montantglobal::numeric - montantsalarial::numeric) / 100.0 , 2) as mt_pat from prod_quadrarh.lignesbulletin where to_char(periode::date, 'YYYY')::int > 2015 ; -- Régul pour Almaviva UPDATE w_hp_0 SET base = 0 WHERE code = '.BAS_0' AND nombre < 1.1 AND current_database() IN ('icti_548','icti_549','icti_550','icti_551','icti_552','icti_553','icti_554') ; DROP TABLE IF EXISTS w_hp ; CREATE TEMP TABLE w_hp AS SELECT w_profils.contrat_mois_id, w_profils.contrat_id, w_profils.salarie_id, w_profils.profil_id, w_profils.matricule AS code_original, w_profils.matricule AS matricule, w_profils.numeroemploye, w_hp_0.sequence, w_profils.date_debut, least(w_profils.date_fin, base.cti_last_day(w_profils.date_debut)) as date_fin, w_profils.date_paie, w_profils.mois, w_hp_0.code, t_rubriques.oid AS rubrique_id, t_rubriques.p_detail, t_rubriques.p_cumul, t_rubriques.c_base * case when @t_rubriques.c_base != 1 then coalesce(case when proratiser_conversion then w_profils.ratio_theo else 1.0 end, 1.0) else 1.0 end * CASE WHEN p_base THEN (CASE s_base WHEN 0 THEN w_hp_0.nombre WHEN 1 THEN w_hp_0.base WHEN 2 THEN w_hp_0.tx_sal WHEN 3 THEN w_hp_0.mt_sal WHEN 4 THEN w_hp_0.tx_pat WHEN 5 THEN w_hp_0.mt_pat WHEN 6 THEN w_hp_0.mt_sal + w_hp_0.mt_pat WHEN 7 THEN w_hp_0.mt_sal - w_hp_0.mt_pat WHEN 8 THEN w_hp_0.mt_pat - w_hp_0.mt_sal END) else 0 end AS base, t_rubriques.c_nombre * case when @t_rubriques.c_nombre != 1 then coalesce(case when proratiser_conversion then w_profils.ratio_theo else 1.0 end, 1.0) else 1.0 end * CASE WHEN p_nombre THEN (CASE s_nombre WHEN 0 THEN w_hp_0.nombre WHEN 1 THEN w_hp_0.base WHEN 2 THEN w_hp_0.tx_sal WHEN 3 THEN w_hp_0.mt_sal WHEN 4 THEN w_hp_0.tx_pat WHEN 5 THEN w_hp_0.mt_pat WHEN 6 THEN w_hp_0.mt_sal + w_hp_0.mt_pat WHEN 7 THEN w_hp_0.mt_sal - w_hp_0.mt_pat WHEN 8 THEN w_hp_0.mt_pat - w_hp_0.mt_sal END) else 0 end AS nombre, t_rubriques.c_heures_contrat * case when @t_rubriques.c_heures_contrat != 1 then coalesce(case when proratiser_conversion then w_profils.ratio_theo else 1.0 end, 1.0) else 1.0 end * CASE WHEN p_heures_contrat then (CASE s_heures_contrat WHEN 0 THEN w_hp_0.nombre WHEN 1 THEN w_hp_0.base WHEN 2 THEN w_hp_0.tx_sal WHEN 3 THEN w_hp_0.mt_sal WHEN 4 THEN w_hp_0.tx_pat WHEN 5 THEN w_hp_0.mt_pat WHEN 6 THEN w_hp_0.mt_sal + w_hp_0.mt_pat WHEN 7 THEN w_hp_0.mt_sal - w_hp_0.mt_pat WHEN 8 THEN w_hp_0.mt_pat - w_hp_0.mt_sal END) else 0 end AS heure_contrat, t_rubriques.c_heures_payees * case when @t_rubriques.c_heures_payees != 1 then coalesce(case when proratiser_conversion then w_profils.ratio_theo else 1.0 end, 1.0) else 1.0 end * CASE WHEN p_heures_payees then (CASE s_heures_payees WHEN 0 THEN w_hp_0.nombre WHEN 1 THEN w_hp_0.base WHEN 2 THEN w_hp_0.tx_sal WHEN 3 THEN w_hp_0.mt_sal WHEN 4 THEN w_hp_0.tx_pat WHEN 5 THEN w_hp_0.mt_pat WHEN 6 THEN w_hp_0.mt_sal + w_hp_0.mt_pat WHEN 7 THEN w_hp_0.mt_sal - w_hp_0.mt_pat WHEN 8 THEN w_hp_0.mt_pat - w_hp_0.mt_sal END) else 0 end AS heure_payee, t_rubriques.c_heures_travaillees * case when @t_rubriques.c_heures_travaillees != 1 then coalesce(case when proratiser_conversion then w_profils.ratio_theo else 1.0 end, 1.0) else 1.0 end * CASE WHEN p_heures_travaillees then (CASE s_heures_travaillees WHEN 0 THEN w_hp_0.nombre WHEN 1 THEN w_hp_0.base WHEN 2 THEN w_hp_0.tx_sal WHEN 3 THEN w_hp_0.mt_sal WHEN 4 THEN w_hp_0.tx_pat WHEN 5 THEN w_hp_0.mt_pat WHEN 6 THEN w_hp_0.mt_sal + w_hp_0.mt_pat WHEN 7 THEN w_hp_0.mt_sal - w_hp_0.mt_pat WHEN 8 THEN w_hp_0.mt_pat - w_hp_0.mt_sal END) else 0 end AS heure_travaillee, t_rubriques.c_masse_salariale * (CASE WHEN p_masse_salariale THEN (CASE s_masse_salariale WHEN 0 THEN w_hp_0.nombre WHEN 1 THEN w_hp_0.base WHEN 2 THEN w_hp_0.tx_sal WHEN 3 THEN w_hp_0.mt_sal WHEN 4 THEN w_hp_0.tx_pat WHEN 5 THEN w_hp_0.mt_pat WHEN 6 THEN w_hp_0.mt_sal + w_hp_0.mt_pat WHEN 7 THEN w_hp_0.mt_sal - w_hp_0.mt_pat WHEN 8 THEN w_hp_0.mt_pat - w_hp_0.mt_sal END) else 0 end) AS masse_salariale, t_rubriques.c_brut * (CASE WHEN p_brut THEN (CASE s_brut WHEN 0 THEN w_hp_0.nombre WHEN 1 THEN w_hp_0.base WHEN 2 THEN w_hp_0.tx_sal WHEN 3 THEN w_hp_0.mt_sal WHEN 4 THEN w_hp_0.tx_pat WHEN 5 THEN w_hp_0.mt_pat WHEN 6 THEN w_hp_0.mt_sal + w_hp_0.mt_pat WHEN 7 THEN w_hp_0.mt_sal - w_hp_0.mt_pat WHEN 8 THEN w_hp_0.mt_pat - w_hp_0.mt_sal END) else 0 end) AS montant_brut, t_rubriques.c_frais_imposables * (case when p_frais_imposables then (CASE s_frais_imposables WHEN 0 THEN w_hp_0.nombre WHEN 1 THEN w_hp_0.base WHEN 2 THEN w_hp_0.tx_sal WHEN 3 THEN w_hp_0.mt_sal WHEN 4 THEN w_hp_0.tx_pat WHEN 5 THEN w_hp_0.mt_pat WHEN 6 THEN w_hp_0.mt_sal + w_hp_0.mt_pat WHEN 7 THEN w_hp_0.mt_sal - w_hp_0.mt_pat WHEN 8 THEN w_hp_0.mt_pat - w_hp_0.mt_sal END) else 0 end) AS montant_frais_imposables, t_rubriques.coefficient_txs * (case when p_cotisation_salarie then w_hp_0.tx_sal else 0 end) AS taux_sal, t_rubriques.c_cotisation_salarie * (case when p_cotisation_salarie then (CASE s_cotisation_salarie WHEN 0 THEN w_hp_0.nombre WHEN 1 THEN w_hp_0.base WHEN 2 THEN w_hp_0.tx_sal WHEN 3 THEN w_hp_0.mt_sal WHEN 4 THEN w_hp_0.tx_pat WHEN 5 THEN w_hp_0.mt_pat WHEN 6 THEN w_hp_0.mt_sal + w_hp_0.mt_pat WHEN 7 THEN w_hp_0.mt_sal - w_hp_0.mt_pat WHEN 8 THEN w_hp_0.mt_pat - w_hp_0.mt_sal END) else 0 end) AS montant_cot_sal, t_rubriques.coefficient_txp * (case when p_cotisation_patronale then w_hp_0.tx_pat else 0 end) AS taux_pat, t_rubriques.c_cotisation_patronale * (case when p_cotisation_patronale then (CASE s_cotisation_patronale WHEN 0 THEN w_hp_0.nombre WHEN 1 THEN w_hp_0.base WHEN 2 THEN w_hp_0.tx_sal WHEN 3 THEN w_hp_0.mt_sal WHEN 4 THEN w_hp_0.tx_pat WHEN 5 THEN w_hp_0.mt_pat WHEN 6 THEN w_hp_0.mt_sal + w_hp_0.mt_pat WHEN 7 THEN w_hp_0.mt_sal - w_hp_0.mt_pat WHEN 8 THEN w_hp_0.mt_pat - w_hp_0.mt_sal END) else 0 end) AS montant_cot_pat, t_rubriques.c_od_net_salarie * (CASE WHEN p_od_net_salarie THEN (CASE s_od_net_salarie WHEN 0 THEN w_hp_0.nombre WHEN 1 THEN w_hp_0.base WHEN 2 THEN w_hp_0.tx_sal WHEN 3 THEN w_hp_0.mt_sal WHEN 4 THEN w_hp_0.tx_pat WHEN 5 THEN w_hp_0.mt_pat WHEN 6 THEN w_hp_0.mt_sal + w_hp_0.mt_pat WHEN 7 THEN w_hp_0.mt_sal - w_hp_0.mt_pat WHEN 8 THEN w_hp_0.mt_pat - w_hp_0.mt_sal END) ELSE 0 END) AS od_net, t_rubriques.c_od_net_patronale * (CASE WHEN p_od_net_patronale THEN (CASE s_od_net_patronale WHEN 0 THEN w_hp_0.nombre WHEN 1 THEN w_hp_0.base WHEN 2 THEN w_hp_0.tx_sal WHEN 3 THEN w_hp_0.mt_sal WHEN 4 THEN w_hp_0.tx_pat WHEN 5 THEN w_hp_0.mt_pat WHEN 6 THEN w_hp_0.mt_sal + w_hp_0.mt_pat WHEN 7 THEN w_hp_0.mt_sal - w_hp_0.mt_pat WHEN 8 THEN w_hp_0.mt_pat - w_hp_0.mt_sal END) ELSE 0 END) AS od_net_p, t_rubriques.c_avantage_nature * (CASE WHEN p_avantage_nature THEN (CASE s_avantage_nature WHEN 0 THEN w_hp_0.nombre WHEN 1 THEN w_hp_0.base WHEN 2 THEN w_hp_0.tx_sal WHEN 3 THEN w_hp_0.mt_sal WHEN 4 THEN w_hp_0.tx_pat WHEN 5 THEN w_hp_0.mt_pat WHEN 6 THEN w_hp_0.mt_sal + w_hp_0.mt_pat WHEN 7 THEN w_hp_0.mt_sal - w_hp_0.mt_pat WHEN 8 THEN w_hp_0.mt_pat - w_hp_0.mt_sal END) ELSE 0 END) AS avt_nat, t_rubriques.c_net_imposable * (CASE WHEN p_net_imposable THEN (CASE s_net_imposable WHEN 0 THEN w_hp_0.nombre WHEN 1 THEN w_hp_0.base WHEN 2 THEN w_hp_0.tx_sal WHEN 3 THEN w_hp_0.mt_sal WHEN 4 THEN w_hp_0.tx_pat WHEN 5 THEN w_hp_0.mt_pat WHEN 6 THEN w_hp_0.mt_sal + w_hp_0.mt_pat WHEN 7 THEN w_hp_0.mt_sal - w_hp_0.mt_pat WHEN 8 THEN w_hp_0.mt_pat - w_hp_0.mt_sal END) ELSE 0 END) AS net_imposable, t_rubriques.c_net_a_payer * (CASE WHEN p_net_a_payer THEN (CASE s_net_a_payer WHEN 0 THEN w_hp_0.nombre WHEN 1 THEN w_hp_0.base WHEN 2 THEN w_hp_0.tx_sal WHEN 3 THEN w_hp_0.mt_sal WHEN 4 THEN w_hp_0.tx_pat WHEN 5 THEN w_hp_0.mt_pat WHEN 6 THEN w_hp_0.mt_sal + w_hp_0.mt_pat WHEN 7 THEN w_hp_0.mt_sal - w_hp_0.mt_pat WHEN 8 THEN w_hp_0.mt_pat - w_hp_0.mt_sal END) ELSE 0 END) AS net_a_payer FROM w_hp_0 JOIN w_profils ON 1=1 AND w_profils.numeroemploye = w_hp_0.numeroemploye AND w_profils.mois = w_hp_0.mois_paie AND w_profils.sequence = w_hp_0.sequence JOIN rh.t_rubriques ON t_rubriques.code_original = w_hp_0.code where 1=1 -- AND t_hbns.datehist >= rhp('rhprovider_start')::date -- Filtrer les lignes générées systématiquement tous les mois par Sage pour chaque salarié même s'il n'y a rien. AND (false OR p_nombre OR p_base OR p_heures_contrat OR p_heures_payees OR p_heures_travaillees OR p_masse_salariale OR p_brut OR p_avantage_nature OR p_frais_imposables OR p_cotisation_salarie OR p_cotisation_patronale OR p_od_net_salarie OR p_od_net_patronale OR p_net_imposable OR p_net_a_payer) ; -- Génération paie SELECT base.cti_stash_table_indexes('rh', 'p_historique_paie') ; TRUNCATE rh.p_historique_paie ; INSERT INTO rh.p_historique_paie( code_original, age_id, base, nombre, contrat_id, contrat_mois_id, date_debut, date_fin, date_paie, mois_activite, mois_paie, heure_contrat, heure_payee, heure_travaillee, montant_avantage_nature, montant_brut, montant_masse_salariale, montant_cotisation_patronale, montant_cotisation_salarie, montant_frais_imposables, montant_net_a_payer_salarie, montant_net_imposable_salarie, montant_od_net_salarie, organisme_cotisation_id, profil_id, rubrique_id, compte_id, salarie_id, taux_cotisation_patronale, taux_cotisation_salarie) SELECT w_hp.matricule||w_hp.sequence||w_hp.date_paie::date as code_original, date_part('year', age(w_hp.date_fin, date_naissance)) AS age_id, w_hp.base, w_hp.nombre, w_hp.contrat_id, w_hp.contrat_mois_id, w_hp.date_paie, w_hp.date_paie, w_hp.date_paie AS date_paie, w_hp.mois AS mois_activite, w_hp.mois AS mois_paie, w_hp.heure_contrat, w_hp.heure_payee, w_hp.heure_travaillee, w_hp.avt_nat AS montant_avantage_nature, w_hp.montant_brut AS montant_brut, w_hp.masse_salariale as montant_masse_salariale, w_hp.montant_cot_pat AS montant_cotisation_patronale, w_hp.montant_cot_sal AS montant_cotisation_salarie, w_hp.montant_frais_imposables, w_hp.net_a_payer AS montant_net_a_payer_salarie, w_hp.net_imposable AS montant_net_imposable_salarie, w_hp.od_net AS montant_od_net_salarie, 0 AS organisme_cotisation_id, w_hp.profil_id, w_hp.rubrique_id, 0 AS compte_id, w_hp.salarie_id, w_hp.taux_pat AS taux_cotisation_patronale, w_hp.taux_sal AS taux_cotisation_salarie FROM w_hp JOIN rh.p_salaries ON p_salaries.oid = w_hp.salarie_id WHERE p_detail ; SELECT base.cti_stash_pop_table_indexes('rh', 'p_historique_paie') ; -- 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_avantage_nature) as total_avantage_nature, bool_or(p_cumul and p_brut) as total_brut, bool_or(p_cumul and p_masse_salariale) as total_masse_salariale, bool_or(p_cumul and p_cotisation_patronale) as total_cot_pat, bool_or(p_cumul and p_cotisation_salarie) as total_cot_sal, bool_or(p_cumul and p_net_a_payer) as total_payer, bool_or(p_cumul and p_net_imposable) as total_imposable, bool_or(p_cumul and p_heures_contrat) as total_h_contrat, bool_or(p_cumul and p_heures_payees) as total_h_payees, bool_or(p_cumul and p_heures_travaillees) as total_h_travaillees 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.matricule||w_hp.sequence||w_hp.date_paie::date as code_original, w_hp.matricule, w_hp.date_paie as date, w_hp.mois, round(sum(case when p_cumul then avt_nat else 0 end), 2) AS hcum_avantage_nature, round(sum(case when p_cumul then montant_brut else 0 end), 2) AS hcum_brut, round(sum(case when p_cumul then masse_salariale else 0 end), 2) AS hcum_masse_salariale, round(sum(case when p_cumul then montant_cot_pat else 0 end), 2) AS hcum_cotisation_patronale, round(sum(case when p_cumul then montant_cot_sal else 0 end), 2) AS hcum_cotisation_salarie, 0::numeric AS hcum_frais_imposables, round(sum(case when p_cumul then net_a_payer else 0 end), 2) AS hcum_net_a_payer_salarie, round(sum(case when p_cumul then net_imposable else 0 end), 2) AS hcum_net_imposable_salarie, sum(case when p_cumul then heure_contrat else 0 end) AS hcum_heures_contrat, sum(case when p_cumul then heure_payee else 0 end) AS hcum_heures_payees, sum(case when p_cumul then heure_travaillee else 0 end) AS hcum_heures_travaillees, 0::numeric AS montant_od_net_salarie FROM w_hp WHERE p_cumul GROUP BY 1,2,3,4 ; -- A la demande de Mme CONSTANTIN, ajout des heures d'astreinte travaillees (B092 et BF92) au total des heures payées Quadra car mal paramétré dans Quadra. WITH correction as( SELECT w_hp.matricule||w_hp.sequence||w_hp.date_paie::date as code_original, sum(base) AS heures_astreinte FROM w_hp WHERE code in ('B092_0', 'BF92_0') GROUP BY 1 HAVING sum(base) != 0) UPDATE w_totaux SET hcum_heures_payees = hcum_heures_payees + heures_astreinte FROM correction WHERE w_totaux.code_original = correction.code_original ; -- 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, 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_avantage_nature, montant_brut, montant_masse_salariale, montant_cotisation_patronale, montant_cotisation_salarie, montant_frais_imposables, montant_net_a_payer_salarie, montant_net_imposable_salarie, montant_od_net_salarie, organisme_cotisation_id, profil_id, rubrique_id, compte_id, salarie_id, taux_cotisation_patronale, taux_cotisation_salarie) SELECT subq.code_original, 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, 0 AS base, 0 AS nombre, case when total_h_contrat then COALESCE(hcum_heures_contrat, 0) - subq.heure_contrat else 0.0 end AS heure_contrat, case when total_h_payees then COALESCE(hcum_heures_payees,0) - subq.heure_payee else 0.0 end AS heure_payee, case when total_h_travaillees then COALESCE(hcum_heures_travaillees,0) - subq.heure_travaillee else 0.0 end AS heure_travaillee, case when total_avantage_nature then COALESCE(hcum_avantage_nature,0) - subq.montant_avantage_nature else 0.0 end AS montant_avantage_nature, case when total_brut then COALESCE(hcum_brut,0) - subq.montant_brut else 0.0 end AS montant_brut, case when total_masse_salariale then COALESCE(hcum_masse_salariale, 0) - subq.montant_masse_salariale else 0.0 end AS montant_masse_salariale, case when total_cot_pat then COALESCE(hcum_cotisation_patronale,0) - subq.montant_cotisation_patronale else 0.0 end AS montant_cotisation_patronale, case when total_cot_sal then COALESCE(hcum_cotisation_salarie,0) - subq.montant_cotisation_salarie else 0.0 end AS montant_cotisation_salarie, 0 AS montant_frais_imposables, case when total_payer then COALESCE(hcum_net_a_payer_salarie,0) - subq.montant_net_a_payer_salarie else 0.0 end AS montant_net_a_payer_salarie, case when total_imposable then COALESCE(hcum_net_imposable_salarie,0) - subq.montant_net_imposable_salarie else 0.0 end AS montant_net_imposable_salarie, 0 AS montant_od_net_salarie, subq.organisme_cotisation_id AS organisme_cotisation_id, subq.profil_id AS profil_id, (SELECT oid FROM rh.t_rubriques WHERE code = 'C000') AS rubrique_id, 0 AS compte_id, subq.salarie_id AS salarie_id, 0 AS taux_cotisation_patronale, 0 AS taux_cotisation_salarie FROM ( SELECT p_historique_paie.code_original, 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, sum(heure_contrat) AS heure_contrat, sum(heure_payee) AS heure_payee, sum(heure_travaillee) AS heure_travaillee, sum(montant_avantage_nature) AS montant_avantage_nature, sum(montant_brut) AS montant_brut, sum(montant_masse_salariale) AS montant_masse_salariale, sum(montant_cotisation_patronale) AS montant_cotisation_patronale, sum(montant_cotisation_salarie) AS montant_cotisation_salarie, 0 AS montant_frais_imposables, sum(montant_net_a_payer_salarie) AS montant_net_a_payer_salarie, sum(montant_net_imposable_salarie) AS montant_net_imposable_salarie, 0 AS montant_od_net_salarie, p_historique_paie.organisme_cotisation_id, p_historique_paie.profil_id, (SELECT oid FROM rh.t_rubriques WHERE code = 'C000'), p_historique_paie.salarie_id, 0 AS taux_cotisation_patronale, 0 AS taux_cotisation_salarie FROM rh.p_historique_paie JOIN rh.p_salaries ON p_salaries.oid = p_historique_paie.salarie_id GROUP BY 1,2,3,4,5,6,7,8,9,10,11, 24,25,26,27) AS subq JOIN w_totaux ON w_totaux.code_original = subq.code_original JOIN w_cumul ON true WHERE 1!=1 OR case when total_avantage_nature then COALESCE(hcum_avantage_nature,0) - subq.montant_avantage_nature != 0 else false end OR case when total_brut then COALESCE(hcum_brut,0) - subq.montant_brut != 0 else false end OR case when total_masse_salariale then COALESCE(hcum_masse_salariale,0) - subq.montant_masse_salariale != 0 else false end OR case when total_payer then COALESCE(hcum_net_a_payer_salarie,0) - subq.montant_net_a_payer_salarie != 0 else false end OR case when total_imposable then COALESCE(hcum_net_imposable_salarie,0) - subq.montant_net_imposable_salarie != 0 else false end OR case when total_cot_pat then COALESCE(hcum_cotisation_patronale,0) - subq.montant_cotisation_patronale != 0 else false end OR case when total_cot_sal then COALESCE(hcum_cotisation_salarie,0) - subq.montant_cotisation_salarie != 0 else false end OR case when total_h_contrat then COALESCE(hcum_heures_contrat, 0) - subq.heure_contrat != 0 else false end OR case when total_h_payees then COALESCE(hcum_heures_payees,0) - subq.heure_payee != 0 else false end OR case when total_h_travaillees then COALESCE(hcum_heures_travaillees,0) - subq.heure_travaillee != 0 else false end ; ]]>