= 1 then 'TC' else 'TP'||(sfr_etp::numeric * 100.0) end as type_temps_travail_code_original,
sfr_etp
from prod_meta4.sfr_h_hr_salaire
group by 1,2,3,4,5)
select
sfr_id_hr as mat,
case when row_number() over w = 1 then '1900-01-01'::date else sfr_dt_start end as date_debut,
(case when row_number() over wd = 1 then '2099-12-31'::date else lead(sfr_dt_start) over w - '1 day'::interval end)::date as date_fin,
*
from lite_roles
window w as (partition by sfr_id_hr order by sfr_dt_start),
wd as (partition by sfr_id_hr order by sfr_dt_start desc)
;
]]>
0).
with bulletins_fj_0 as (
select
rownum,
max(date_fin - date_debut + 1) / max((base.cti_last_day(date_debut) - base.cti_first_day(date_debut) + 1.0)) as proratisation_jour,
sum(case when rub = 'sfr_nb_days_per_year' then base else 0 end) as sfr_nb_days_per_year,
sum(case when rub = 'cviva_coef_prorata_tp' then base else 0 end) as cviva_coef_prorata_tp,
sum(case when rub = 'sfr_base_sal_payslip' then base else 0 end) as sfr_base_sal_payslip,
sum(case when rub = 'sfr_base_sal_payslip' then mt_sal else 0 end) as sfr_base_sal_payslip_mt_sal
from w_hp_1
where rub in ('sfr_nb_days_per_year', 'cviva_coef_prorata_tp', 'sfr_base_sal_payslip')
group by 1
) , bulletins_fj as (
select
rownum,
cviva_coef_prorata_tp as heures_contrat
from bulletins_fj_0
where 1=1
and sfr_base_sal_payslip_mt_sal != 0 -- bulletins forfait jour ET ...
and sfr_base_sal_payslip = 0 -- ... ayant une base à 0 dans la rubrique standard des heures contrat.
)
update w_hp_1 set
base = bulletins_fj.heures_contrat
from bulletins_fj
where 1=1
and w_hp_1.rownum = bulletins_fj.rownum
and rub = 'sfr_base_sal_payslip'
;
-- Alimenter les cotisations séparées.
insert into w_hp_1
select
w_hst_bul.cti_bul,
arr_rownum[1] as rownum,
sco_id_hr as mat,
sfr_ac_fund_retraite.sco_or_hr_period,
to_date(sco_dt_allocation, 'DD/MM/YYYY') as sco_dt_allocation,
to_date(sco_dt_payment, 'DD/MM/YYYY') as sco_dt_payment,
sco_pay_freq_alloc,
sco_pay_freq_paym,
id_currency,
to_date(sco_dt_start_slice, 'DD/MM/YYYY') as date_debut,
to_date(sco_dt_end_slice, 'DD/MM/YYYY') as date_fin,
sfr_etp,
lower(sfr_id_fund||'_'||sfr_id_cat_retraite||'_'||sfr_id_contribution_type||'_'||sfr_id_base_type) as rub,
sfr_name_contribution as rub_texte,
sfr_amount_base::numeric as base,
sfr_emp_part::numeric as tx_sal,
sfr_amount_employee::numeric as mt_sal,
sfr_comp_part::numeric as tx_pat,
sfr_amount_company::numeric as mt_pat
from prod_meta4.sfr_ac_fund_retraite
join w_hst_bul on 1=1
and w_hst_bul.mat = sfr_ac_fund_retraite.sco_id_hr
and w_hst_bul.sco_or_hr_period = sfr_ac_fund_retraite.sco_or_hr_period
and w_hst_bul.date_debut = to_date(sfr_ac_fund_retraite.sco_dt_start_slice, 'DD/MM/YYYY')
and w_hst_bul.date_fin = to_date(sfr_ac_fund_retraite.sco_dt_end_slice, 'DD/MM/YYYY')
;
insert into w_hp_1
select
w_hst_bul.cti_bul,
arr_rownum[1] as rownum,
sco_id_hr as mat,
sfr_ac_fund_prevoyance.sco_or_hr_period,
to_date(sco_dt_allocation, 'DD/MM/YYYY') as sco_dt_allocation,
to_date(sco_dt_payment, 'DD/MM/YYYY') as sco_dt_payment,
sco_pay_freq_alloc,
sco_pay_freq_paym,
id_currency,
to_date(sco_dt_start_slice, 'DD/MM/YYYY') as date_debut,
to_date(sco_dt_end_slice, 'DD/MM/YYYY') as date_fin,
sfr_etp,
lower(replace(sfr_id_fund, ' ', '_')||'_'||sfr_id_cat_prevoyance||'_'||sfr_id_contribution_type||'_'||sfr_id_base_type) as rub,
sfr_name_contribution as rub_texte,
sfr_amount_base::numeric as base,
sfr_emp_part::numeric as tx_sal,
sfr_amount_employee::numeric as mt_sal,
sfr_comp_part::numeric as tx_pat,
sfr_amount_company::numeric as mt_pat
from prod_meta4.sfr_ac_fund_prevoyance
join w_hst_bul on 1=1
and w_hst_bul.mat = sfr_ac_fund_prevoyance.sco_id_hr
and w_hst_bul.sco_or_hr_period = sfr_ac_fund_prevoyance.sco_or_hr_period
and w_hst_bul.date_debut = to_date(sfr_ac_fund_prevoyance.sco_dt_start_slice, 'DD/MM/YYYY')
and w_hst_bul.date_fin = to_date(sfr_ac_fund_prevoyance.sco_dt_end_slice, 'DD/MM/YYYY')
;
-- Insertion des absences SS.
insert into w_hp_1
select
w_hst_bul.cti_bul,
arr_rownum[1] as rownum,
std_id_hr as mat,
std_or_hr_period,
to_date(sco_dt_allocation, 'DD/MM/YYYY') as sco_dt_allocation,
to_date(sco_dt_payment, 'DD/MM/YYYY') as sco_dt_payment,
sco_pay_freq_alloc,
sco_pay_freq_paym,
'EUR'::text as id_currency,
to_date(cfr_dt_start_slice, 'DD/MM/YYYY') as date_debut,
to_date(cfr_dt_end_slice, 'DD/MM/YYYY') as date_fin,
sfr_etp,
lower('a_'||sco_id_incidence) as rub,
'Absence '||sco_id_incidence as rub_texte,
sfr_num_cal_days::numeric as base, -- sfr_num_working_hours n'est pas fiable
0::numeric as tx_sal,
0::numeric as mt_sal,
0::numeric as tx_pat,
0::numeric as mt_pat
from prod_meta4.sfr_h_detail_abs_ss
join w_hst_bul on 1=1
and w_hst_bul.mat = sfr_h_detail_abs_ss.std_id_hr
and w_hst_bul.sco_or_hr_period = sfr_h_detail_abs_ss.std_or_hr_period
and w_hst_bul.date_debut = to_date(sfr_h_detail_abs_ss.cfr_dt_start_slice, 'DD/MM/YYYY')
and w_hst_bul.date_fin = to_date(sfr_h_detail_abs_ss.cfr_dt_end_slice, 'DD/MM/YYYY')
;
-- Insertion des absences
-- Déduction
insert into w_hp_1
select
w_hst_bul.cti_bul,
arr_rownum[1] as rownum,
sfr_id_hr as mat,
sfr_or_hr_period,
to_date(sfr_dt_allocation, 'DD/MM/YYYY') as sco_dt_allocation,
to_date(sfr_dt_payment, 'DD/MM/YYYY') as sco_dt_payment,
sfr_pay_freq_alloc,
sfr_pay_freq_paym,
sfr_id_currency,
to_date(sfr_dt_start_slice, 'DD/MM/YYYY') as date_debut,
to_date(sfr_dt_end_slice, 'DD/MM/YYYY') as date_fin,
sfr_etp,
lower('a_'||sfr_id_entitlement) as rub,
'Absence '||sfr_id_entitlement as rub_texte,
sfr_num_units_deduction::numeric as base,
sfr_rte_deduction::numeric as tx_sal,
sfr_amt_deduction::numeric * -1 as mt_sal,
0::numeric as tx_pat,
0::numeric as mt_pat
from prod_meta4.sfr_ac_hrp_absence
join w_hst_bul on 1=1
and w_hst_bul.mat = sfr_ac_hrp_absence.sfr_id_hr
and w_hst_bul.sco_or_hr_period = sfr_ac_hrp_absence.sfr_or_hr_period
and base.cti_overlaps(w_hst_bul.date_debut, w_hst_bul.date_fin, to_date(sfr_ac_hrp_absence.sfr_dt_start_slice, 'DD/MM/YYYY'), to_date(sfr_ac_hrp_absence.sfr_dt_end_slice, 'DD/MM/YYYY'))
-- Ca ne marche pas :
-- and w_hst_bul.date_debut = to_date(sfr_ac_hrp_absence.sfr_dt_start_slice, 'DD/MM/YYYY')
-- and w_hst_bul.date_fin = to_date(sfr_ac_hrp_absence.sfr_dt_end_slice, 'DD/MM/YYYY')
where sfr_amt_deduction::numeric != 0
;
-- et Paiements.
insert into w_hp_1
select
w_hst_bul.cti_bul,
arr_rownum[1] as rownum,
sfr_id_hr as mat,
sfr_or_hr_period,
to_date(sfr_dt_allocation, 'DD/MM/YYYY') as sco_dt_allocation,
to_date(sfr_dt_payment, 'DD/MM/YYYY') as sco_dt_payment,
sfr_pay_freq_alloc,
sfr_pay_freq_paym,
sfr_id_currency,
to_date(sfr_dt_start_slice, 'DD/MM/YYYY') as date_debut,
to_date(sfr_dt_end_slice, 'DD/MM/YYYY') as date_fin,
sfr_etp,
lower('p_'||sfr_id_entitlement) as rub,
'Paiement '||sfr_id_entitlement as rub_texte,
sfr_num_units_payment::numeric as base,
sfr_rte_payment::numeric as tx_sal,
sfr_amt_payment::numeric as mt_sal,
0::numeric as tx_pat,
0::numeric as mt_pat
from prod_meta4.sfr_ac_hrp_absence
join w_hst_bul on 1=1
and w_hst_bul.mat = sfr_ac_hrp_absence.sfr_id_hr
and w_hst_bul.sco_or_hr_period = sfr_ac_hrp_absence.sfr_or_hr_period
and base.cti_overlaps(w_hst_bul.date_debut, w_hst_bul.date_fin, to_date(sfr_ac_hrp_absence.sfr_dt_start_slice, 'DD/MM/YYYY'), to_date(sfr_ac_hrp_absence.sfr_dt_end_slice, 'DD/MM/YYYY'))
-- Ca ne marche pas :
-- and w_hst_bul.date_debut = to_date(sfr_ac_hrp_absence.sfr_dt_start_slice, 'DD/MM/YYYY')
-- and w_hst_bul.date_fin = to_date(sfr_ac_hrp_absence.sfr_dt_end_slice, 'DD/MM/YYYY')
where sfr_amt_payment::numeric != 0
;
-- Contrats.
DROP TABLE IF EXISTS w_hst_contrat
;
CREATE TEMP TABLE w_hst_contrat AS
SELECT
cti_cnt,
std_id_hr as mat,
std_or_hr_period,
to_date(std_dt_start, 'DD/MM/YYYY') as date_debut,
case when row_number() over w != 1 and to_date(std_dt_end, 'DD/MM/YYYY') = '4000-01-01'::date
then lag(to_date(std_dt_start, 'DD/MM/YYYY')) over w - '1 day'::interval
else coalesce(nullif(to_date(std_dt_end, 'DD/MM/YYYY'), '4000-01-01'::date), '2099-12-31'::date)
end as date_fin,
std_id_cont_type,
std_id_break_reason
from w_std_int_work_contract
window w as (partition by std_id_hr order by to_date(std_dt_start, 'DD/MM/YYYY') desc)
;
DROP TABLE IF EXISTS w_hst_qua
;
CREATE TEMP TABLE w_hst_qua AS
with lite_roles as (
select
sco_id_hr,
sco_or_hr_role,
sco_or_hr_period,
to_date(sco_dt_start, 'DD/MM/YYYY') as sco_dt_start,
substr(md5(sco_n_rolefra), 1, 5) as qualification_code_original
from prod_meta4.sco_hr_role
group by 1,2,3,4,5)
select
sco_id_hr as mat,
case when row_number() over w = 1 then '1900-01-01'::date else sco_dt_start end as date_debut,
(case when row_number() over wd = 1 then '2099-12-31'::date else lead(sco_dt_start) over w - '1 day'::interval end)::date as date_fin,
*
from lite_roles
window w as (partition by sco_id_hr order by sco_dt_start),
wd as (partition by sco_id_hr order by sco_dt_start desc)
;
DROP TABLE IF EXISTS w_hst_ser
;
CREATE TEMP TABLE w_hst_ser AS
with lite_roles as (
select
sco_id_hr,
sco_or_hr_role,
sco_or_hr_period,
to_date(sco_dt_start_slice, 'DD/MM/YYYY') as sco_dt_start_slice,
sfr_id_work_unit as service_code_original
from prod_meta4.sco_ac_hr_role
group by 1,2,3,4,5)
select
sco_id_hr as mat,
case when row_number() over w = 1 then '1900-01-01'::date else sco_dt_start_slice end as date_debut,
(case when row_number() over wd = 1 then '2099-12-31'::date else lead(sco_dt_start_slice) over w - '1 day'::interval end)::date as date_fin,
*
from lite_roles
window w as (partition by sco_id_hr order by sco_dt_start_slice),
wd as (partition by sco_id_hr order by sco_dt_start_slice desc)
;
DROP TABLE IF EXISTS w_hst_sta
;
CREATE TEMP TABLE w_hst_sta AS
with lite_roles as (
select
sfr_id_hr,
sfr_or_hr_role,
to_date(sfr_dt_start, 'DD/MM/YYYY') as sfr_dt_start,
sfr_id_cat_lab_agree as statut_code_original
from prod_meta4.sfr_h_hr_job_classification
group by 1,2,3,4)
select
sfr_id_hr as mat,
case when row_number() over w = 1 then '1900-01-01'::date else sfr_dt_start end as date_debut,
(case when row_number() over wd = 1 then '2099-12-31'::date else lead(sfr_dt_start) over w - '1 day'::interval end)::date as date_fin,
*
from lite_roles
window w as (partition by sfr_id_hr order by sfr_dt_start),
wd as (partition by sfr_id_hr order by sfr_dt_start desc)
;
-- Limites salariés.
DROP TABLE IF EXISTS w_lim_sal
;
CREATE TEMP TABLE w_lim_sal AS
select
mat,
min(date_debut) as date_debut,
max(date_fin) as date_fin
from (
select
mat,
min(date_debut) as date_debut,
coalesce(nullif(max(date_fin), '2099-12-31'::date), max(subq.ec)) as date_fin -- 2099-12-31 correspond à "contrat en cours" => on met le mois de paie en cours (et surtout pas current_date).
from w_hst_contrat
join (select max(date_fin) as ec from w_hst_bul) as subq on true
group by 1
UNION ALL
select
mat,
min(date_debut) as date_debut,
max(date_fin) as date_fin
from w_hst_bul
group by 1
) as subq
group by 1
;
CREATE INDEX i_lim_sal_mat ON w_lim_sal USING btree(mat);
CREATE INDEX i_lim_sal_dates ON w_lim_sal USING btree(date_debut, date_fin);
DROP TABLE IF EXISTS w_evt_mois
;
CREATE TEMP TABLE w_evt_mois AS
with ValidDates as (
select mat, date_debut::date as date from w_hst_contrat
union select mat, date_fin::date as date from w_hst_contrat
union select mat, date_debut::date as date from w_hst_bul
union select mat, date_fin::date as date from w_hst_bul
union select mat, date_debut::date as date from w_hst_qua
union select mat, date_fin::date as date from w_hst_qua
union select mat, date_debut::date as date from w_hst_ser
union select mat, date_fin::date as date from w_hst_ser
union select mat, date_debut::date as date from w_hst_sta
union select mat, date_fin::date as date from w_hst_sta
union select mat, date_debut::date as date from w_hst_ttt
union select mat, date_fin::date as date from w_hst_ttt
)
, ValidDateRanges1 as (
select *, case when lead(date) over w = date + '1 day'::interval then false else true end as correct,
(case when lead(date) over w = date + '1 day'::interval then null else (date + '1 day'::interval) end)::date as date_debut,
(case when lead(date) over w = date + '1 day'::interval then null else (lead(date) over w - '1 day'::interval) end)::date as date_fin
from ValidDates
window w as (partition by mat order by Date)
)
, ValidDateRanges as (
select mat, date_debut as ValidFrom, date_fin as ValidTo from ValidDateRanges1 where correct
union
select mat, date, date from ValidDates
)
, detail as (
select
E.mat,
OU.cti_cnt,
L.cti_bul,
--null::text as cti_bul,
w_hst_qua.qualification_code_original,
w_hst_ser.service_code_original,
w_hst_sta.statut_code_original,
w_hst_ttt.type_temps_travail_code_original,
D.ValidFrom,
D.ValidTo,
e.date_fin as max_date
from w_lim_sal E
join ValidDateRanges D on E.mat=D.mat and base.cti_overlaps(E.date_debut::date, E.date_fin::date, D.ValidFrom, D.ValidTo)
left join w_hst_contrat OU on true
and OU.mat=D.mat
and base.cti_overlaps(OU.date_debut::date, OU.date_fin::date, D.ValidFrom, D.ValidTo)
left join w_hst_bul L on true
and L.mat=D.mat
and base.cti_overlaps(L.date_debut::date, L.date_fin::date, D.ValidFrom, D.ValidTo)
left join w_hst_qua on true
and w_hst_qua.mat=D.mat
and base.cti_overlaps(w_hst_qua.date_debut::date, w_hst_qua.date_fin::date, D.ValidFrom, D.ValidTo)
left join w_hst_ser on true
and w_hst_ser.mat=D.mat
and base.cti_overlaps(w_hst_ser.date_debut::date, w_hst_ser.date_fin::date, D.ValidFrom, D.ValidTo)
left join w_hst_sta on true
and w_hst_sta.mat=D.mat
and base.cti_overlaps(w_hst_sta.date_debut::date, w_hst_sta.date_fin::date, D.ValidFrom, D.ValidTo)
left join w_hst_ttt on true
and w_hst_ttt.mat=D.mat
and base.cti_overlaps(w_hst_ttt.date_debut::date, w_hst_ttt.date_fin::date, D.ValidFrom, D.ValidTo)
where false
or cti_cnt is not null
or cti_bul is not null)
, detail2 as (
select
mat,
cti_cnt, -- contrat
cti_bul, -- bulletin.
qualification_code_original,
service_code_original,
statut_code_original,
type_temps_travail_code_original,
mois,
min(greatest(validfrom, date_debut)) as date_debut,
max(least(validto, date_fin)) as date_fin,
(max(least(validto, date_fin)) - min(greatest(validfrom, date_debut)) + 1)::numeric / (max(date_fin) - min(date_debut) + 1)::numeric as ratio_temps
from detail
left join base.p_calendrier_mois on true
and base.cti_overlaps(validfrom, validto, date_debut, date_fin)
and date_fin <= max_date
group by 1,2,3,4,5,6,7,8)
select
mat,
cti_cnt, -- contrat
coalesce(cti_cnt,
(max(case when cti_cnt is null then null else ARRAY[extract(epoch from date_fin)::numeric, cti_cnt] end) over wb)[2], -- sinon on prend la valeur renseignée la plus proche dans le passé
(min(case when cti_cnt is null then null else ARRAY[extract(epoch from date_fin)::numeric, cti_cnt] end) over wf)[2], -- sinon on prend la valeur renseignée la plus proche dans le futur
null -- sinon on prend null
) as cti_cnt_all,
cti_bul, -- bulletin.
qualification_code_original,
service_code_original,
statut_code_original,
type_temps_travail_code_original,
mois,
date_debut,
date_fin,
ratio_temps
from detail2
window wb as (PARTITION BY mat ORDER BY date_fin rows unbounded preceding), -- sélectionne les lignes précédentes
wf as (PARTITION BY mat ORDER BY date_fin rows between current row and unbounded following) -- sélectionne les lignes suivantes
;
]]>
= 1 then 'TC' else 'TP'||(sfr_etp::numeric * 100.0) end,
case when sfr_etp >= 1 then 'TC' else 'TP'||(sfr_etp::numeric * 100.0) end,
case when sfr_etp >= 1 then 'Temps Complet' else 'Temps Partiel '||(sfr_etp::numeric * 100.0)||' %' end,
substr(case when sfr_etp >= 1 then 'Temps Complet' else 'Temps Partiel '||(sfr_etp::numeric * 100.0)||' %' end, 1, 50)
FROM prod_meta4.sfr_h_hr_salaire
WHERE case when sfr_etp >= 1 then 'TC' else 'TP'||(sfr_etp::numeric * 100.0) end NOT IN (SELECT code_original FROM rh.t_types_temps_travail)
GROUP BY 1,2,3,4
;
]]>