return: text lang: plpgsql src: | DECLARE result TEXT; BEGIN with eff_perm_0 as ( select p_contrats_mois.oid, p_contrats_mois.salarie_id, p_contrats_mois.mois_activite, sum(case when bool_and(p_profils.type_contrat_section_code[9] = 'CDI' and p_profils.type_temps_travail_section_code[9] = 'TC') then case when to_char(p_contrats_mois.date_fin, 'YYYYMM') != p_contrats_mois.mois_activite then base.cti_last_day((p_contrats_mois.mois_activite||'01')::date) else p_contrats_mois.date_fin end - case when to_char(p_contrats_mois.date_debut, 'YYYYMM') != p_contrats_mois.mois_activite then base.cti_first_day((p_contrats_mois.mois_activite||'01')::date) else p_contrats_mois.date_debut end + 1 else 0 end ) over (partition by p_contrats_mois.salarie_id, substr(p_contrats_mois.mois_activite, 1, 4) order by p_contrats_mois.date_debut) as duree from rh.p_contrats_mois join rh.p_profil_contrat_mois on p_profil_contrat_mois.contrat_mois_id = p_contrats_mois.oid join rh.p_profils on p_profils.oid = p_profil_contrat_mois.profil_id group by 1,2,3, p_contrats_mois.date_debut, p_contrats_mois.date_fin, p_contrats_mois.mois_activite window w as (partition by p_contrats_mois.salarie_id, p_contrats_mois.mois_activite)) , eff_perm_1 as ( select array_agg(oid) as arr_oid, salarie_id, mois_activite, case when sum(base.cti_last_day((mois_activite||'01')::date) - base.cti_first_day((substr(mois_activite, 1, 4)||'0101')::date)) + 1 = duree then 1 else 0 end as effectif_permanent from eff_perm_0 GROUP BY salarie_id, mois_activite, duree ) , eff_perm as ( select unnest(arr_oid) as oid, effectif_permanent from eff_perm_1 ) update rh.p_contrats_mois set effectif_permanent = eff_perm.effectif_permanent from eff_perm where true and p_contrats_mois.oid = eff_perm.oid and p_contrats_mois.effectif_permanent is distinct from eff_perm.effectif_permanent ; return 'OK'; END;