<?xml version="1.0" encoding="ISO-8859-15"?>
|
|
<ROOT>
|
|
<NODE name="INIT" label="INITIALISATIONS">
|
|
<NODE name="INIT" type="common" />
|
|
<NODE label="Suppression des doublons">
|
|
<sqlcmd><![CDATA[
|
|
|
|
drop table if exists w_std_person
|
|
;
|
|
create temp table w_std_person as
|
|
with all_dup as (
|
|
select
|
|
row_number() over (order by right(pg_class.relname, 6)) as cti_mat,
|
|
right(pg_class.relname, 6) as mois_donnee,
|
|
std_id_person,
|
|
std_n_family_name_1,
|
|
std_n_first_name,
|
|
sfr_n_maiden_name,
|
|
std_dt_birth,
|
|
std_id_gender
|
|
from prod_meta4.std_person
|
|
join pg_class on pg_class.oid = std_person.tableoid)
|
|
select
|
|
std_id_person,
|
|
(max(array[mois_donnee::text, std_n_family_name_1]))[2] as std_n_family_name_1,
|
|
(max(array[mois_donnee::text, std_n_first_name]))[2] as std_n_first_name,
|
|
(max(array[mois_donnee::text, sfr_n_maiden_name]))[2] as sfr_n_maiden_name,
|
|
(max(array[mois_donnee::text, std_dt_birth]))[2] as std_dt_birth,
|
|
(max(array[mois_donnee::text, std_id_gender]))[2] as std_id_gender
|
|
from all_dup
|
|
group by 1
|
|
;
|
|
|
|
drop table if exists w_std_int_work_contract
|
|
;
|
|
create temp table w_std_int_work_contract as
|
|
with all_dup as (
|
|
select
|
|
row_number() over (order by right(pg_class.relname, 6)) as cti_cnt,
|
|
right(pg_class.relname, 6) as mois_donnee,
|
|
std_id_hr,
|
|
std_or_hr_period,
|
|
std_dt_start,
|
|
std_dt_end,
|
|
std_id_cont_type,
|
|
std_id_break_reason
|
|
from prod_meta4.std_int_work_contract
|
|
join pg_class on pg_class.oid = std_int_work_contract.tableoid)
|
|
select
|
|
std_id_hr,
|
|
std_or_hr_period,
|
|
std_dt_start,
|
|
max(cti_cnt) as cti_cnt,
|
|
(max(array[mois_donnee::text, std_dt_end]))[2] as std_dt_end,
|
|
(max(array[mois_donnee::text, std_id_cont_type]))[2] as std_id_cont_type,
|
|
(max(array[mois_donnee::text, std_id_break_reason]))[2] as std_id_break_reason
|
|
from all_dup
|
|
group by 1,2,3
|
|
;
|
|
|
|
DROP TABLE IF EXISTS w_hst_ttt
|
|
;
|
|
|
|
CREATE TEMP TABLE w_hst_ttt 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,
|
|
case when sfr_etp >= 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)
|
|
;
|
|
|
|
]]></sqlcmd>
|
|
</NODE>
|
|
<NODE label="Pré-traitements des données">
|
|
<sqlcmd><![CDATA[
|
|
|
|
-- table brute de l'historique de la paie.
|
|
drop table if exists w_hp_0
|
|
;
|
|
create temp table w_hp_0 as
|
|
select
|
|
null::bigint as rownum,
|
|
null::text[] as cols,
|
|
null::text[] as vals
|
|
limit 0
|
|
;
|
|
|
|
select meta4_create_array_table('prod_meta4.cviva_ac_hr_period', 'w_hp_0', 9);
|
|
select meta4_create_array_table('prod_meta4.cviva_ac_hr_period_1', 'w_hp_0', 0);
|
|
select meta4_create_array_table('prod_meta4.sco_ac_hr_period', 'w_hp_0', 10);
|
|
select meta4_create_array_table('prod_meta4.sco_ac_hr_period_1', 'w_hp_0', 0);
|
|
select meta4_create_array_table('prod_meta4.sco_ac_hr_period_2', 'w_hp_0', 0);
|
|
select meta4_create_array_table('prod_meta4.sco_ac_hr_period_3', 'w_hp_0', 0);
|
|
select meta4_create_array_table('prod_meta4.sco_ac_hr_period_4', 'w_hp_0', 0);
|
|
select meta4_create_array_table('prod_meta4.sfr_ac_hr_period', 'w_hp_0', 43);
|
|
|
|
-- Une ligne d'entête = un bulletin car il est éclaté en autant de colonnes (une ligne de bulletin papier = une colonne du CSV).
|
|
-- Mais attention des fois un bulletin peut être mis sur 4 lignes (même dates de début et de fin) sans que l'on sache pourquoi...
|
|
drop table if exists w_hp_header
|
|
;
|
|
create temp table w_hp_header as
|
|
select
|
|
row_number() over (order by ctid) as rownum,
|
|
sco_id_hr,
|
|
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 sco_dt_start_slice,
|
|
to_date(sco_dt_end_slice, 'DD/MM/YYYY') as sco_dt_end_slice
|
|
from prod_meta4.sco_ac_hr_period
|
|
;
|
|
|
|
CREATE INDEX i_hp_header_0 ON w_hp_header USING btree(rownum)
|
|
;
|
|
|
|
-- Bulletins. -- Du coup cti_bul = 1 seule ligne.
|
|
DROP TABLE IF EXISTS w_hst_bul
|
|
;
|
|
|
|
CREATE TEMP TABLE w_hst_bul AS
|
|
select
|
|
array_agg(distinct rownum) as arr_rownum,
|
|
row_number() over (order by sco_dt_start_slice, sco_dt_end_slice) as cti_bul,
|
|
sco_or_hr_period,
|
|
sco_id_hr as mat,
|
|
sco_dt_start_slice as date_debut,
|
|
sco_dt_end_slice as date_fin,
|
|
coalesce(sfr_etp::numeric, 1) as sfr_etp
|
|
from w_hp_header
|
|
left join w_hst_ttt on true
|
|
and w_hst_ttt.mat = w_hp_header.sco_id_hr
|
|
and sco_dt_start_slice::date between w_hst_ttt.date_debut::date and w_hst_ttt.date_fin::date
|
|
group by 3,4,5,6,7
|
|
;
|
|
|
|
drop table if exists w_lignes
|
|
;
|
|
create temp table w_lignes as
|
|
with raw_rubs_0 as (
|
|
select
|
|
rownum,
|
|
unnest(cols) as rub,
|
|
unnest(vals) as val
|
|
from w_hp_0)
|
|
,raw_rubs as (
|
|
select rub
|
|
from raw_rubs_0
|
|
group by 1)
|
|
,raw_params_0 as (
|
|
select
|
|
rub as rub_ori,
|
|
case when rub in ('sco_net', 'sfr_net_imposable', 'sfr_hres_travaillees', 'cviva_coef_prorata_tp', 'sfr_nb_days_per_year') or substr(rub, 1, 8) = 'sfr_ijss' then rub
|
|
else regexp_replace(rub, '^([a-z]*)_([a-z]*)_(.*?)(\_emp|\_e|\_sal|\_comp|\_c|\_pat)?$', E'\\1_\\3', 'g') end as new_rub,
|
|
rub in ('cviva_coef_prorata_tp', 'sfr_nb_days_per_year') or regexp_replace(rub, '^([a-z]*)_([a-z]*)_.*', E'\\2', 'g') in ('bas', 'base', 'num') as est_base,
|
|
regexp_replace(rub, '^([a-z]*)_([a-z]*)_.*', E'\\2', 'g') in ('rte', 'taux') as est_taux,
|
|
rub in ('sco_net', 'sfr_net_imposable', 'sfr_hres_travaillees')
|
|
or substr(rub, 1, 8) = 'sfr_ijss'
|
|
or regexp_replace(rub, '^([a-z]*)_([a-z]*)_.*', E'\\2', 'g') in ('amt', 'mnt', 'tot') as est_montant,
|
|
regexp_replace(rub, '^([a-z]*)_([a-z]*)_.*', E'\\2', 'g') in ('amt', 'mnt') as est_mnt, -- mnt (amt inclue) vs ...
|
|
regexp_replace(rub, '^([a-z]*)_([a-z]*)_.*', E'\\2', 'g') in ('tot') as est_tot, -- ... tot
|
|
case regexp_replace(rub, '(.*)(\_emp|\_e|\_sal|\_comp|\_c|\_pat)$', E'\\2', 'g')
|
|
when '_e' then 'S'
|
|
when '_emp' then 'S'
|
|
when '_sal' then 'S'
|
|
when '_c' then 'P'
|
|
when '_comp' then 'P'
|
|
when '_pat' then 'P'
|
|
else 'U' end as rub_type
|
|
from raw_rubs)
|
|
,raw_params as (
|
|
select
|
|
rub_ori,
|
|
new_rub,
|
|
est_base,
|
|
est_taux,
|
|
case when bool_or(est_mnt) over w and bool_or(est_tot) over w -- lorsqu'une new_rub possède à la fois un mnt et un tot, on privilégie le mnt.
|
|
then est_mnt
|
|
else est_montant end as est_montant,
|
|
rub_type
|
|
from raw_params_0
|
|
window w as (partition by new_rub))
|
|
select
|
|
rownum,
|
|
rub_ori,
|
|
new_rub,
|
|
est_base,
|
|
est_taux,
|
|
est_montant,
|
|
rub_type,
|
|
val
|
|
from raw_rubs_0
|
|
join raw_params on raw_params.rub_ori = raw_rubs_0.rub
|
|
;
|
|
|
|
CREATE INDEX w_lignes_0 ON w_lignes USING btree(rownum)
|
|
;
|
|
|
|
drop table if exists w_hp_1
|
|
;
|
|
create temp table w_hp_1 as
|
|
with exploded_buls as (
|
|
select
|
|
unnest(arr_rownum) as rownum,
|
|
cti_bul,
|
|
sco_or_hr_period,
|
|
mat,
|
|
date_debut,
|
|
date_fin,
|
|
sfr_etp
|
|
from w_hst_bul
|
|
), exploded_header_buls as (
|
|
select
|
|
exploded_buls.rownum,
|
|
exploded_buls.cti_bul,
|
|
exploded_buls.sco_or_hr_period,
|
|
exploded_buls.mat,
|
|
w_hp_header.sco_dt_allocation,
|
|
w_hp_header.sco_dt_payment,
|
|
w_hp_header.sco_pay_freq_alloc,
|
|
w_hp_header.sco_pay_freq_paym,
|
|
w_hp_header.id_currency,
|
|
exploded_buls.date_debut,
|
|
exploded_buls.date_fin,
|
|
exploded_buls.sfr_etp
|
|
from exploded_buls
|
|
join w_hp_header on w_hp_header.rownum = exploded_buls.rownum
|
|
)
|
|
select
|
|
exploded_header_buls.cti_bul,
|
|
exploded_header_buls.rownum,
|
|
exploded_header_buls.mat,
|
|
sco_or_hr_period,
|
|
sco_dt_allocation,
|
|
sco_dt_payment,
|
|
sco_pay_freq_alloc,
|
|
sco_pay_freq_paym,
|
|
id_currency,
|
|
exploded_header_buls.date_debut,
|
|
exploded_header_buls.date_fin,
|
|
exploded_header_buls.sfr_etp,
|
|
new_rub as rub,
|
|
null::text as rub_texte,
|
|
sum(case when est_base then base.cti_to_number(val) else 0 end) * (case when new_rub IN ('cviva_coef_prorata_tp') then 151.67 else 1 end) as base, -- permet d'avoir des heures contrat.
|
|
sum(case when est_taux and rub_type != 'P' then base.cti_to_number(val) else 0 end) as tx_sal,
|
|
sum(case when est_montant and rub_type != 'P' then base.cti_to_number(val) else 0 end) as mt_sal,
|
|
sum(case when est_taux and rub_type != 'S' then base.cti_to_number(val) else 0 end) as tx_pat,
|
|
sum(case when est_montant and rub_type != 'S' then base.cti_to_number(val) else 0 end) as mt_pat
|
|
from exploded_header_buls
|
|
join w_lignes on w_lignes.rownum = exploded_header_buls.rownum
|
|
group by 1,2,3,4,5,6,7,8,9,10,11,12,13
|
|
having 1!=1
|
|
OR sum(case when est_montant and rub_type != 'P' then base.cti_to_number(val) else 0 end) != 0
|
|
OR sum(case when est_montant and rub_type != 'S' then base.cti_to_number(val) else 0 end) != 0
|
|
OR new_rub IN ('cviva_coef_prorata_tp') -- permet d'avoir des heures contrat.
|
|
;
|
|
|
|
-- Alimentation du flag est_forfait_jour (SFR_NB_DAYS_PER_YEAR > 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
|
|
;
|
|
|
|
]]></sqlcmd>
|
|
</NODE>
|
|
<NODE label="Mise à jour des informations permanentes">
|
|
<sqlcmd><![CDATA[
|
|
|
|
-- Màj des rubriques
|
|
INSERT INTO rh.t_rubriques(code_original, code, texte, texte_court, rang_edition)
|
|
SELECT rub, rub, coalesce(rub_texte, rub), substr(coalesce(rub_texte, rub), 1, 50), -1
|
|
FROM w_hp_1
|
|
WHERE rub NOT IN (SELECT code_original FROM rh.t_rubriques)
|
|
GROUP BY 1,2,3,4,5
|
|
;
|
|
|
|
-- Màj des motifs de début de contrat
|
|
-- INSERT INTO rh.t_motifs_debut_contrat(code_original, code, texte, texte_court)
|
|
-- SELECT std_id_cont_type, std_id_cont_type, std_id_cont_type, substr(std_id_cont_type, 1, 50)
|
|
-- FROM w_std_int_work_contract
|
|
-- WHERE 1=1
|
|
-- AND std_id_cont_type is not null
|
|
-- AND std_id_cont_type NOT IN (SELECT code_original FROM rh.t_motifs_debut_contrat)
|
|
-- GROUP BY 1,2,3,4
|
|
-- ;
|
|
|
|
-- Màj des motifs de fin de contrat.
|
|
INSERT INTO rh.t_motifs_fin_contrat(code_original, code, texte, texte_court)
|
|
SELECT std_id_break_reason, std_id_break_reason, std_id_break_reason, substr(std_id_break_reason, 1, 50)
|
|
FROM w_std_int_work_contract
|
|
WHERE 1=1
|
|
AND std_id_break_reason is not null
|
|
AND std_id_break_reason NOT IN (SELECT code_original FROM rh.t_motifs_fin_contrat)
|
|
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 std_id_cont_type, std_id_cont_type, std_id_cont_type, substr(std_id_cont_type, 1, 50)
|
|
FROM w_std_int_work_contract
|
|
WHERE 1=1
|
|
AND std_id_cont_type is not null
|
|
AND std_id_cont_type NOT IN (SELECT code_original FROM rh.t_types_contrat)
|
|
GROUP BY 1,2,3,4
|
|
;
|
|
|
|
-- Mise à jour des qualifications.
|
|
INSERT INTO rh.t_qualifications(code_original, code, texte, texte_court)
|
|
select substr(md5(sco_n_rolefra), 1, 5), substr(md5(sco_n_rolefra), 1, 5), sco_n_rolefra, substr(sco_n_rolefra, 1, 50)
|
|
from prod_meta4.sco_hr_role
|
|
WHERE true
|
|
and substr(md5(sco_n_rolefra), 1, 5) NOT IN (SELECT code_original FROM rh.t_qualifications)
|
|
GROUP BY 1,2,3,4
|
|
;
|
|
|
|
-- Mise à jour des services.
|
|
INSERT INTO rh.t_services(code_original, code, texte, texte_court)
|
|
select sfr_id_work_unit, sfr_id_work_unit, sfr_id_work_unit, sfr_id_work_unit
|
|
from prod_meta4.sco_ac_hr_role
|
|
WHERE true
|
|
and sfr_id_work_unit NOT IN (SELECT code_original FROM rh.t_services)
|
|
GROUP BY 1,2,3,4
|
|
;
|
|
|
|
INSERT INTO rh.t_statuts(code_original, code, texte, texte_court)
|
|
select sfr_id_cat_lab_agree, sfr_id_cat_lab_agree, sfr_id_cat_lab_agree, sfr_id_cat_lab_agree
|
|
from prod_meta4.sfr_h_hr_job_classification
|
|
WHERE true
|
|
and sfr_id_cat_lab_agree 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 sfr_etp >= 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
|
|
;
|
|
|
|
]]></sqlcmd>
|
|
</NODE>
|
|
</NODE>
|
|
<NODE name="PROD" label="RECUPERATION DES DONNEES DE PRODUCTION">
|
|
<NODE label="Chiffrier">
|
|
<sqlcmd><![CDATA[
|
|
|
|
TRUNCATE rh.p_chiffrier_production
|
|
;
|
|
|
|
INSERT INTO rh.p_chiffrier_production (entreprise_id, etablissement_id, mois, nombre_salaries, montant_brut, nombre_heures)
|
|
SELECT
|
|
1,
|
|
1,
|
|
to_char(sco_dt_payment, 'YYYYMM')::numeric,
|
|
count(DISTINCT mat),
|
|
sum(CASE WHEN p_brut and p_cumul THEN (CASE s_brut
|
|
WHEN 0 THEN base
|
|
WHEN 1 THEN base
|
|
WHEN 2 THEN tx_sal
|
|
WHEN 3 THEN mt_sal
|
|
WHEN 4 THEN tx_pat
|
|
WHEN 5 THEN mt_pat
|
|
WHEN 6 THEN mt_sal + mt_pat
|
|
WHEN 7 THEN mt_sal - mt_pat
|
|
WHEN 8 THEN -mt_sal + mt_pat
|
|
END) ELSE 0 END * c_brut),
|
|
sum(CASE WHEN p_heures_payees and p_cumul THEN (CASE s_heures_payees
|
|
WHEN 0 THEN base
|
|
WHEN 1 THEN base
|
|
WHEN 2 THEN tx_sal
|
|
WHEN 3 THEN mt_sal
|
|
WHEN 4 THEN tx_pat
|
|
WHEN 5 THEN mt_pat
|
|
WHEN 6 THEN mt_sal + mt_pat
|
|
WHEN 7 THEN mt_sal - mt_pat
|
|
WHEN 8 THEN -mt_sal + mt_pat
|
|
END) ELSE 0 END * c_heures_payees)
|
|
FROM w_hp_1
|
|
JOIN rh.t_rubriques ON t_rubriques.code_original = w_hp_1.rub
|
|
WHERE 1=1
|
|
AND (p_cumul OR p_detail)
|
|
GROUP BY 1,2,3
|
|
;
|
|
|
|
]]></sqlcmd>
|
|
</NODE>
|
|
<NODE label="Pré-traitements">
|
|
<sqlcmd><![CDATA[
|
|
|
|
]]></sqlcmd>
|
|
</NODE>
|
|
<NODE label="Profils">
|
|
<sqlcmd><![CDATA[
|
|
|
|
DROP TABLE IF EXISTS w_profils
|
|
;
|
|
|
|
CREATE TEMP TABLE w_profils AS
|
|
select
|
|
0 as profil_id,
|
|
w_evt_mois.cti_bul,
|
|
w_hst_bul.date_debut as bul_date_debut,
|
|
w_hst_bul.date_fin as bul_date_fin,
|
|
w_evt_mois.cti_cnt,
|
|
w_evt_mois.cti_cnt_all,
|
|
case when w_evt_mois.cti_cnt is not null then w_hst_contrat.date_debut else null end as cnt_date_debut,
|
|
case when w_evt_mois.cti_cnt is not null then w_hst_contrat.date_fin else null end as cnt_date_fin,
|
|
w_evt_mois.mat,
|
|
w_evt_mois.mois,
|
|
w_evt_mois.date_debut,
|
|
w_evt_mois.date_fin,
|
|
(w_evt_mois.date_fin - w_evt_mois.date_debut + 1)
|
|
/ (base.cti_last_day((w_evt_mois.mois||'01')::date) - base.cti_first_day((w_evt_mois.mois||'01')::date) + 1) -- divisé par nb jours total du mois
|
|
* 1::numeric / 10000::numeric as etp, -- multiplié par l'ETP du contrat. @todo ETP forcé à 1.
|
|
case when w_evt_mois.cti_cnt is null then 1 else 0 end as est_hors_periode,
|
|
-- Données du Profil CTI
|
|
chr(1)||'*' AS categorie_socio_professionnelle_code_original,
|
|
chr(1)||'*' AS code_emploi_code_original,
|
|
chr(1)||'*' as grille_code_original,
|
|
chr(1)||'*' AS grille_groupe_code_original,
|
|
chr(1)||'*' AS groupe_cotisant_code_original,
|
|
chr(1)||'*' AS motif_debut_code_original,
|
|
coalesce(std_id_break_reason, chr(1)||'*') AS motif_fin_code_original,
|
|
coalesce(w_evt_mois.qualification_code_original, chr(1)||'*') AS qualification_code_original,
|
|
coalesce(w_evt_mois.service_code_original, chr(1)||'*') AS service_code_original,
|
|
chr(1)||'*' AS societe_interim_code_original,
|
|
chr(1)||'*' AS specialite_code_original,
|
|
coalesce(w_evt_mois.statut_code_original, chr(1)||'*') AS statut_code_original,
|
|
coalesce(std_id_cont_type, chr(1)||'*') AS type_contrat_code_original,
|
|
chr(1)||'*' AS type_horaire_code_original,
|
|
coalesce(w_evt_mois.type_temps_travail_code_original, chr(1)||'*') AS type_temps_travail_code_original,
|
|
chr(1)||'*' AS section_analytique_code_original,
|
|
chr(1)||'*' AS section_analytique_paie_code_original,
|
|
-- Champs dédiés au public.
|
|
chr(1)||'*' AS unite_fonctionnelle_code_original,
|
|
chr(1)||'*' AS categorie_conge_code_original,
|
|
chr(1)||'*' AS compte_salarie_code_original,
|
|
chr(1)||'*' AS commission_paritaire_code_original,
|
|
chr(1)||'*' AS lettre_budgetaire_code_original,
|
|
chr(1)||'*' AS cadre_emploi_code_original,
|
|
chr(1)||'*' AS filiere_code_original,
|
|
chr(1)||'*' AS categorie_statutaire_code_original
|
|
from w_evt_mois
|
|
left join w_hst_contrat on w_hst_contrat.cti_cnt = w_evt_mois.cti_cnt_all
|
|
left join w_hst_bul on w_hst_bul.cti_bul = w_evt_mois.cti_bul
|
|
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,33,34,35,36,37,38
|
|
;
|
|
|
|
]]></sqlcmd>
|
|
</NODE>
|
|
<NODE name="PROFIL" type="common" />
|
|
<NODE label="Salariés">
|
|
<sqlcmd><![CDATA[
|
|
|
|
DROP TABLE IF EXISTS w_salaries
|
|
;
|
|
|
|
CREATE TEMP TABLE w_salaries AS
|
|
SELECT
|
|
0 as salarie_id,
|
|
rhp('finess') AS finess,
|
|
std_n_family_name_1 as nom,
|
|
std_n_first_name as prenom,
|
|
coalesce(sfr_n_maiden_name, '') as nom_naissance,
|
|
to_date(std_dt_birth, 'DD/MM/YYYY') as date_naissance,
|
|
case when std_id_gender = 1 then 'M' else 'F' end as sexe,
|
|
std_id_person as code,
|
|
std_id_person as code_original,
|
|
std_id_person as matricule,
|
|
t_etablissements.entreprise_id,
|
|
0 AS nationalite_id,
|
|
coalesce(t_codes_postaux.oid, 0) AS code_postal_id,
|
|
0 AS situation_famille_id,
|
|
-- coalesce((max(array[extract(epoch from date_debut), w_profils.profil_id]))[2], 0::bigint) AS profil_id,
|
|
0 as profil_id,
|
|
null::date AS date_debut,
|
|
null::date AS date_fin,
|
|
null::date as date_entree_ets,
|
|
null::date as date_sortie_ets,
|
|
-- Champs dédiés au public.
|
|
null::date AS date_entree_fp,
|
|
null::date AS date_entree_fph,
|
|
0 AS no_adeli,
|
|
0 AS code_cotisation_id,
|
|
0 AS matricule_retraite
|
|
from w_std_person
|
|
--join w_profils on w_profils.pers_mat = pers.pers_mat
|
|
LEFT JOIN rh.t_codes_postaux ON t_codes_postaux.code = '01'
|
|
LEFT JOIN rh.t_etablissements ON t_etablissements.code_original = '01'
|
|
GROUP BY 1,2,3,4,5,6,7,8,9,10,11,12,13,14,15, 17,18,19,20,21,22,23,24
|
|
;
|
|
|
|
]]></sqlcmd>
|
|
</NODE>
|
|
<NODE name="SALARIE" type="common" />
|
|
<NODE label="Màj id salariés">
|
|
<sqlcmd><![CDATA[
|
|
|
|
update w_salaries SET
|
|
salarie_id = p_salaries.oid
|
|
from rh.p_salaries
|
|
where p_salaries.code_original = w_salaries.code_original
|
|
;
|
|
|
|
]]></sqlcmd>
|
|
</NODE>
|
|
<NODE label="Contrats">
|
|
<sqlcmd><![CDATA[
|
|
|
|
TRUNCATE rh.p_contrats
|
|
;
|
|
|
|
ALTER SEQUENCE rh.s_contrats RESTART WITH 1
|
|
;
|
|
|
|
INSERT INTO rh.p_contrats(
|
|
salarie_id,
|
|
date_debut,
|
|
date_fin,
|
|
numero_contrat,
|
|
code_original,
|
|
etablissement_id,
|
|
profil_id)
|
|
SELECT
|
|
p_salaries.oid,
|
|
cnt_date_debut,
|
|
cnt_date_fin,
|
|
w_profils.mat||'-'::text||lpad(w_profils.cti_cnt, 4, '0') AS numero_contrat,
|
|
w_profils.cti_cnt AS code_original,
|
|
0, -- @todo t_etablissements.oid AS etablissement_id,
|
|
coalesce((max(array[extract(epoch from w_profils.date_debut), w_profils.profil_id]))[2], 0::bigint) AS profil_id
|
|
FROM w_profils
|
|
JOIn rh.p_salaries on p_salaries.code_original = w_profils.mat
|
|
-- JOIN rh.t_etablissements ON t_etablissements.code_original = '01'
|
|
WHERE cti_cnt is not null
|
|
GROUP BY 1,2,3,4,5,6
|
|
;
|
|
|
|
-- Màj des dates d'E/S éts.
|
|
WITH es_sal AS (
|
|
select
|
|
salarie_id,
|
|
min(date_debut) as date_debut,
|
|
max(date_fin) as date_fin
|
|
from rh.p_contrats
|
|
group by 1)
|
|
UPDATE rh.p_salaries SET
|
|
date_entree_ets = es_sal.date_debut,
|
|
date_sortie_ets = es_sal.date_fin
|
|
FROM es_sal
|
|
WHERE p_salaries.oid = es_sal.salarie_id
|
|
;
|
|
|
|
-- Màj de l'ancienneté.
|
|
UPDATE rh.p_contrats SET
|
|
anciennete_anterieure_jours = subq.anciennete_anterieure_jours,
|
|
anciennete_anterieure_calculee_mois = subq.anciennete_anterieure_calculee_mois
|
|
FROM (
|
|
select
|
|
numero_contrat,
|
|
coalesce(sum(date_fin - date_debut + 1) over w, 0) AS anciennete_anterieure_jours,
|
|
coalesce(sum(date_fin - date_debut + 1) over w / 30::numeric, 0) AS anciennete_anterieure_calculee_mois
|
|
from rh.p_contrats
|
|
window w as (partition by salarie_id order by date_debut rows between UNBOUNDED PRECEDING and 1 preceding)) AS subq
|
|
WHERE 1=1
|
|
AND p_contrats.numero_contrat = subq.numero_contrat
|
|
;
|
|
|
|
SELECT base.cti_stash_table_indexes('rh.p_contrats_mois')
|
|
;
|
|
|
|
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,
|
|
nombre_heures,
|
|
age_id,
|
|
age_jours,
|
|
anciennete_jours,
|
|
anciennete_mois,
|
|
anciennete_annee_id,
|
|
etablissement_id,
|
|
profil_id)
|
|
SELECT
|
|
p_contrats.salarie_id AS salarie_id,
|
|
p_contrats.oid AS contrat_id,
|
|
w_profils.mois AS mois,
|
|
w_profils.date_debut,
|
|
w_profils.date_fin,
|
|
CASE WHEN p_salaries.date_entree_ets BETWEEN w_profils.date_debut AND w_profils.date_fin THEN 1 ELSE 0 END AS nombre_entrees,
|
|
CASE WHEN p_salaries.date_sortie_ets BETWEEN w_profils.date_debut AND w_profils.date_fin THEN 1 ELSE 0 END AS nombre_departs,
|
|
CASE WHEN p_contrats.date_debut BETWEEN w_profils.date_debut AND w_profils.date_fin THEN 1 ELSE 0 END AS nombre_debut_contrat,
|
|
CASE WHEN p_contrats.date_fin BETWEEN w_profils.date_debut AND w_profils.date_fin THEN 1 ELSE 0 END AS nombre_fin_contrat,
|
|
est_hors_periode,
|
|
CASE WHEN base.cti_first_day(w_profils.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_profils.date_fin) BETWEEN p_contrats.date_debut AND p_contrats.date_fin THEN 1 ELSE 0 END AS present_fin_mois,
|
|
etp AS equivalent_temps_plein,
|
|
etp * t_etablissements.base_calcul_etp as nombre_heures,
|
|
base.cti_age(LEAST(w_profils.date_fin, p_contrats.date_fin), coalesce(p_salaries.date_naissance, '1962-04-18'::date), 'ny') AS age_id,
|
|
least(w_profils.date_fin, p_contrats.date_fin)::date - coalesce(p_salaries.date_naissance, '1962-04-18'::date) AS age_jours,
|
|
-- Ancienneté en jours
|
|
p_contrats.anciennete_anterieure_jours
|
|
+ (w_profils.date_fin - p_contrats.date_debut)
|
|
+ 1 AS anciennete_jours,
|
|
-- Ancienneté en mois
|
|
GREATEST(p_contrats.anciennete_anterieure_mois, p_contrats.anciennete_anterieure_calculee_mois)
|
|
+ base.cti_age(date_trunc('month', w_profils.date_fin::date)::date, date_trunc('month', p_contrats.date_debut)::date, 'nm')
|
|
+ 1 AS anciennete_mois,
|
|
-- Ancienneté en années
|
|
floor(
|
|
(GREATEST(p_contrats.anciennete_anterieure_mois, p_contrats.anciennete_anterieure_calculee_mois) / 12)
|
|
+ (base.cti_age(date_trunc('month',w_profils.date_fin::date)::date, date_trunc('month',p_contrats.date_debut)::date, 'nm') + 1) / 12
|
|
) AS anciennete_annee_id,
|
|
0, -- @todo as p_contrats.etablissement_id,
|
|
w_profils.profil_id
|
|
FROM w_profils
|
|
JOIN rh.p_contrats ON p_contrats.code_original = w_profils.cti_cnt_all
|
|
JOIN rh.p_salaries ON p_contrats.salarie_id = p_salaries.oid
|
|
left JOIN rh.t_etablissements ON p_contrats.etablissement_id = t_etablissements.oid
|
|
GROUP BY 1,2,3,4,5,6,7,8,9,10,11,12,13,14,15,16,17,18,19,20,21
|
|
;
|
|
|
|
SELECT base.cti_stash_pop_table_indexes('rh.p_contrats_mois')
|
|
;
|
|
|
|
]]></sqlcmd>
|
|
</NODE>
|
|
<NODE label="Historique de la paie">
|
|
<sqlcmd><![CDATA[
|
|
|
|
DROP TABLE IF EXISTS w_hp_3
|
|
;
|
|
|
|
CREATE TEMP TABLE w_hp_3 AS
|
|
SELECT
|
|
cti_bul,
|
|
rownum,
|
|
mat,
|
|
date_debut,
|
|
date_fin,
|
|
sco_dt_payment as date_paie,
|
|
t_rubriques.oid as rubrique_id,
|
|
t_rubriques.p_detail,
|
|
t_rubriques.p_cumul,
|
|
sum(CASE WHEN p_base THEN (CASE s_base
|
|
WHEN 0 THEN base
|
|
WHEN 1 THEN base
|
|
WHEN 2 THEN tx_sal
|
|
WHEN 3 THEN mt_sal
|
|
WHEN 4 THEN tx_pat
|
|
WHEN 5 THEN mt_pat
|
|
WHEN 6 THEN mt_sal + mt_pat
|
|
WHEN 7 THEN mt_sal - mt_pat
|
|
WHEN 8 THEN -mt_sal + mt_pat
|
|
END) ELSE 0 END * c_base * (case when c_base != 1 then sfr_etp else 1 end)) AS base,
|
|
sum(CASE WHEN p_nombre THEN (CASE s_nombre
|
|
WHEN 0 THEN base
|
|
WHEN 1 THEN base
|
|
WHEN 2 THEN tx_sal
|
|
WHEN 3 THEN mt_sal
|
|
WHEN 4 THEN tx_pat
|
|
WHEN 5 THEN mt_pat
|
|
WHEN 6 THEN mt_sal + mt_pat
|
|
WHEN 7 THEN mt_sal - mt_pat
|
|
WHEN 8 THEN -mt_sal + mt_pat
|
|
END) ELSE 0 END * c_nombre * (case when c_nombre != 1 then sfr_etp else 1 end)) AS nombre,
|
|
sum(CASE WHEN p_heures_contrat THEN (CASE s_heures_contrat
|
|
WHEN 0 THEN base
|
|
WHEN 1 THEN base
|
|
WHEN 2 THEN tx_sal
|
|
WHEN 3 THEN mt_sal
|
|
WHEN 4 THEN tx_pat
|
|
WHEN 5 THEN mt_pat
|
|
WHEN 6 THEN mt_sal + mt_pat
|
|
WHEN 7 THEN mt_sal - mt_pat
|
|
WHEN 8 THEN -mt_sal + mt_pat
|
|
END) ELSE 0 END * c_heures_contrat) AS heures_contrat,
|
|
sum(CASE WHEN p_heures_payees THEN (CASE s_heures_payees
|
|
WHEN 0 THEN base
|
|
WHEN 1 THEN base
|
|
WHEN 2 THEN tx_sal
|
|
WHEN 3 THEN mt_sal
|
|
WHEN 4 THEN tx_pat
|
|
WHEN 5 THEN mt_pat
|
|
WHEN 6 THEN mt_sal + mt_pat
|
|
WHEN 7 THEN mt_sal - mt_pat
|
|
WHEN 8 THEN -mt_sal + mt_pat
|
|
END) ELSE 0 END * c_heures_payees) AS heures_payees,
|
|
sum(CASE WHEN p_heures_travaillees THEN (CASE s_heures_travaillees
|
|
WHEN 0 THEN base
|
|
WHEN 1 THEN base
|
|
WHEN 2 THEN tx_sal
|
|
WHEN 3 THEN mt_sal
|
|
WHEN 4 THEN tx_pat
|
|
WHEN 5 THEN mt_pat
|
|
WHEN 6 THEN mt_sal + mt_pat
|
|
WHEN 7 THEN mt_sal - mt_pat
|
|
WHEN 8 THEN -mt_sal + mt_pat
|
|
END) ELSE 0 END * c_heures_travaillees) AS heures_travaillees,
|
|
sum(CASE WHEN p_masse_salariale THEN (CASE s_masse_salariale
|
|
WHEN 0 THEN base
|
|
WHEN 1 THEN base
|
|
WHEN 2 THEN tx_sal
|
|
WHEN 3 THEN mt_sal
|
|
WHEN 4 THEN tx_pat
|
|
WHEN 5 THEN mt_pat
|
|
WHEN 6 THEN mt_sal + mt_pat
|
|
WHEN 7 THEN mt_sal - mt_pat
|
|
WHEN 8 THEN -mt_sal + mt_pat
|
|
END) ELSE 0 END * c_masse_salariale) AS montant_masse_salariale,
|
|
sum(CASE WHEN p_brut THEN (CASE s_brut
|
|
WHEN 0 THEN base
|
|
WHEN 1 THEN base
|
|
WHEN 2 THEN tx_sal
|
|
WHEN 3 THEN mt_sal
|
|
WHEN 4 THEN tx_pat
|
|
WHEN 5 THEN mt_pat
|
|
WHEN 6 THEN mt_sal + mt_pat
|
|
WHEN 7 THEN mt_sal - mt_pat
|
|
WHEN 8 THEN -mt_sal + mt_pat
|
|
END) ELSE 0 END * c_brut) AS montant_brut,
|
|
sum(CASE WHEN p_avantage_nature THEN (CASE s_avantage_nature
|
|
WHEN 0 THEN base
|
|
WHEN 1 THEN base
|
|
WHEN 2 THEN tx_sal
|
|
WHEN 3 THEN mt_sal
|
|
WHEN 4 THEN tx_pat
|
|
WHEN 5 THEN mt_pat
|
|
WHEN 6 THEN mt_sal + mt_pat
|
|
WHEN 7 THEN mt_sal - mt_pat
|
|
WHEN 8 THEN -mt_sal + mt_pat
|
|
END) ELSE 0 END * c_avantage_nature) AS montant_avantage_nature,
|
|
sum(CASE WHEN p_frais_imposables THEN (CASE s_frais_imposables
|
|
WHEN 0 THEN base
|
|
WHEN 1 THEN base
|
|
WHEN 2 THEN tx_sal
|
|
WHEN 3 THEN mt_sal
|
|
WHEN 4 THEN tx_pat
|
|
WHEN 5 THEN mt_pat
|
|
WHEN 6 THEN mt_sal + mt_pat
|
|
WHEN 7 THEN mt_sal - mt_pat
|
|
WHEN 8 THEN -mt_sal + mt_pat
|
|
END) ELSE 0 END * c_frais_imposables) AS montant_frais_imposables,
|
|
sum(tx_sal * coefficient_txs) AS taux_cotisation_salarie,
|
|
sum(CASE WHEN p_cotisation_salarie THEN (CASE s_cotisation_salarie
|
|
WHEN 0 THEN base
|
|
WHEN 1 THEN base
|
|
WHEN 2 THEN tx_sal
|
|
WHEN 3 THEN mt_sal
|
|
WHEN 4 THEN tx_pat
|
|
WHEN 5 THEN mt_pat
|
|
WHEN 6 THEN mt_sal + mt_pat
|
|
WHEN 7 THEN mt_sal - mt_pat
|
|
WHEN 8 THEN -mt_sal + mt_pat
|
|
END) ELSE 0 END * c_cotisation_salarie) AS montant_cotisation_salarie,
|
|
sum(tx_pat * coefficient_txp) AS taux_cotisation_patronale,
|
|
sum(CASE WHEN p_cotisation_patronale THEN (CASE s_cotisation_patronale
|
|
WHEN 0 THEN base
|
|
WHEN 1 THEN base
|
|
WHEN 2 THEN tx_sal
|
|
WHEN 3 THEN mt_sal
|
|
WHEN 4 THEN tx_pat
|
|
WHEN 5 THEN mt_pat
|
|
WHEN 6 THEN mt_sal + mt_pat
|
|
WHEN 7 THEN mt_sal - mt_pat
|
|
WHEN 8 THEN -mt_sal + mt_pat
|
|
END) ELSE 0 END * c_cotisation_patronale) AS montant_cotisation_patronale,
|
|
sum(CASE WHEN p_od_net_salarie THEN (CASE s_od_net_salarie
|
|
WHEN 0 THEN base
|
|
WHEN 1 THEN base
|
|
WHEN 2 THEN tx_sal
|
|
WHEN 3 THEN mt_sal
|
|
WHEN 4 THEN tx_pat
|
|
WHEN 5 THEN mt_pat
|
|
WHEN 6 THEN mt_sal + mt_pat
|
|
WHEN 7 THEN mt_sal - mt_pat
|
|
WHEN 8 THEN -mt_sal + mt_pat
|
|
END) ELSE 0 END * c_od_net_salarie) AS montant_od_net_salarie,
|
|
sum(CASE WHEN p_od_net_patronale THEN (CASE s_od_net_patronale
|
|
WHEN 0 THEN base
|
|
WHEN 1 THEN base
|
|
WHEN 2 THEN tx_sal
|
|
WHEN 3 THEN mt_sal
|
|
WHEN 4 THEN tx_pat
|
|
WHEN 5 THEN mt_pat
|
|
WHEN 6 THEN mt_sal + mt_pat
|
|
WHEN 7 THEN mt_sal - mt_pat
|
|
WHEN 8 THEN -mt_sal + mt_pat
|
|
END) ELSE 0 END * c_od_net_patronale) AS montant_od_net_patronale,
|
|
sum(CASE WHEN p_net_imposable THEN (CASE s_net_imposable
|
|
WHEN 0 THEN base
|
|
WHEN 1 THEN base
|
|
WHEN 2 THEN tx_sal
|
|
WHEN 3 THEN mt_sal
|
|
WHEN 4 THEN tx_pat
|
|
WHEN 5 THEN mt_pat
|
|
WHEN 6 THEN mt_sal + mt_pat
|
|
WHEN 7 THEN mt_sal - mt_pat
|
|
WHEN 8 THEN -mt_sal + mt_pat
|
|
END) ELSE 0 END * c_net_imposable) AS montant_net_imposable_salarie,
|
|
sum(CASE WHEN p_net_a_payer THEN (CASE s_net_a_payer
|
|
WHEN 0 THEN base
|
|
WHEN 1 THEN base
|
|
WHEN 2 THEN tx_sal
|
|
WHEN 3 THEN mt_sal
|
|
WHEN 4 THEN tx_pat
|
|
WHEN 5 THEN mt_pat
|
|
WHEN 6 THEN mt_sal + mt_pat
|
|
WHEN 7 THEN mt_sal - mt_pat
|
|
WHEN 8 THEN -mt_sal + mt_pat
|
|
END) ELSE 0 END * c_net_a_payer) AS montant_net_a_payer_salarie
|
|
FROM w_hp_1
|
|
JOIN rh.t_rubriques ON t_rubriques.code_original = w_hp_1.rub
|
|
WHERE 1!=1
|
|
OR t_rubriques.p_detail
|
|
OR t_rubriques.p_cumul
|
|
GROUP BY 1,2,3,4,5,6,7,8,9
|
|
;
|
|
|
|
DROP TABLE IF EXISTS w_hp_4
|
|
;
|
|
|
|
CREATE TEMP TABLE w_hp_4 AS
|
|
SELECT
|
|
w_hp_3.cti_bul,
|
|
w_hp_3.rownum,
|
|
w_hp_3.date_debut,
|
|
w_hp_3.date_fin,
|
|
w_hp_3.date_paie,
|
|
p_salaries.oid as salarie_id,
|
|
(max(array[extract(epoch from p_contrats_mois.date_debut), p_contrats_mois.contrat_id]))[2] as contrat_id,
|
|
(max(array[extract(epoch from p_contrats_mois.date_debut), p_contrats_mois.oid]))[2] as contrat_mois_id,
|
|
to_char(w_hp_3.date_debut, 'YYYYMM')::int as mois_activite,
|
|
to_char(w_hp_3.date_paie, 'YYYYMM')::int as mois_paie,
|
|
w_hp_3.rubrique_id,
|
|
0 as compte_id,
|
|
0 as organisme_cotisation_id,
|
|
w_hp_3.base,
|
|
w_hp_3.nombre,
|
|
w_hp_3.heures_contrat,
|
|
w_hp_3.heures_payees,
|
|
w_hp_3.heures_travaillees,
|
|
w_hp_3.montant_masse_salariale,
|
|
w_hp_3.montant_brut,
|
|
w_hp_3.montant_avantage_nature,
|
|
w_hp_3.montant_frais_imposables,
|
|
w_hp_3.taux_cotisation_salarie,
|
|
w_hp_3.montant_cotisation_salarie,
|
|
w_hp_3.taux_cotisation_patronale,
|
|
w_hp_3.montant_cotisation_patronale,
|
|
w_hp_3.montant_od_net_salarie,
|
|
w_hp_3.montant_od_net_patronale,
|
|
w_hp_3.montant_net_imposable_salarie,
|
|
w_hp_3.montant_net_a_payer_salarie
|
|
FROM w_hp_3
|
|
JOIN rh.p_salaries on p_salaries.code_original = w_hp_3.mat
|
|
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_3.date_debut, w_hp_3.date_fin)
|
|
WHERE w_hp_3.p_detail
|
|
GROUP BY 1,2,3,4,5,6, 9,10,11,12,13,14,15,16,17,18,19,20,21,22,23,24,25,26,27,28,29,30
|
|
;
|
|
|
|
TRUNCATE rh.p_historique_paie
|
|
;
|
|
|
|
INSERT INTO rh.p_historique_paie(
|
|
salarie_id,
|
|
contrat_id,
|
|
contrat_mois_id,
|
|
mois_activite,
|
|
date_debut,
|
|
date_fin,
|
|
mois_paie,
|
|
date_paie,
|
|
rubrique_id,
|
|
compte_id,
|
|
organisme_cotisation_id,
|
|
base,
|
|
nombre,
|
|
heure_contrat,
|
|
heure_payee,
|
|
heure_travaillee,
|
|
montant_masse_salariale,
|
|
montant_brut,
|
|
montant_avantage_nature,
|
|
montant_frais_imposables,
|
|
taux_cotisation_salarie,
|
|
montant_cotisation_salarie,
|
|
taux_cotisation_patronale,
|
|
montant_cotisation_patronale,
|
|
montant_od_net_salarie,
|
|
montant_od_net_patronale,
|
|
montant_net_imposable_salarie,
|
|
montant_net_a_payer_salarie)
|
|
SELECT
|
|
salarie_id,
|
|
contrat_id,
|
|
contrat_mois_id,
|
|
mois_activite,
|
|
date_debut,
|
|
date_fin,
|
|
mois_paie,
|
|
date_paie,
|
|
rubrique_id,
|
|
compte_id,
|
|
organisme_cotisation_id,
|
|
base,
|
|
nombre,
|
|
heures_contrat,
|
|
heures_payees,
|
|
heures_travaillees,
|
|
montant_masse_salariale,
|
|
montant_brut,
|
|
montant_avantage_nature,
|
|
montant_frais_imposables,
|
|
taux_cotisation_salarie,
|
|
montant_cotisation_salarie,
|
|
taux_cotisation_patronale,
|
|
montant_cotisation_patronale,
|
|
montant_od_net_salarie,
|
|
montant_od_net_patronale,
|
|
montant_net_imposable_salarie,
|
|
montant_net_a_payer_salarie
|
|
FROM w_hp_4
|
|
;
|
|
|
|
DROP TABLE IF EXISTS w_cible_1
|
|
;
|
|
|
|
CREATE TEMP TABLE w_cible_1 AS
|
|
SELECT
|
|
w_cible.cti_bul,
|
|
w_cible.rownum,
|
|
w_cible.date_debut,
|
|
w_cible.date_fin,
|
|
w_cible.date_paie,
|
|
p_salaries.oid as salarie_id,
|
|
(max(array[extract(epoch from p_contrats_mois.date_debut), p_contrats_mois.contrat_id]))[2] as contrat_id,
|
|
(max(array[extract(epoch from p_contrats_mois.date_debut), p_contrats_mois.oid]))[2] as contrat_mois_id,
|
|
to_char(w_cible.date_debut, 'YYYYMM')::int as mois_activite,
|
|
to_char(w_cible.date_paie, 'YYYYMM')::int as mois_paie,
|
|
0 as compte_id,
|
|
0 as organisme_cotisation_id,
|
|
w_cible.heures_contrat,
|
|
w_cible.heures_payees,
|
|
w_cible.heures_travaillees,
|
|
w_cible.montant_brut,
|
|
w_cible.montant_avantage_nature,
|
|
w_cible.montant_frais_imposables,
|
|
w_cible.montant_cotisation_salarie,
|
|
w_cible.montant_cotisation_patronale,
|
|
w_cible.montant_od_net_salarie,
|
|
w_cible.montant_od_net_patronale,
|
|
w_cible.montant_net_imposable_salarie,
|
|
w_cible.montant_net_a_payer_salarie
|
|
FROM w_hp_3 as w_cible
|
|
JOIN rh.p_salaries on p_salaries.code_original = w_cible.mat
|
|
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_cible.date_debut, w_cible.date_fin)
|
|
WHERE p_cumul
|
|
GROUP BY 1,2,3,4,5,6, 9,10,11,12,13,14,15,16,17,18,19,20,21,22,23,24
|
|
;
|
|
|
|
DROP TABLE IF EXISTS w_cible_2
|
|
;
|
|
|
|
CREATE TEMP TABLE w_cible_2 AS
|
|
SELECT
|
|
cti_bul,
|
|
rownum,
|
|
salarie_id,
|
|
contrat_id,
|
|
contrat_mois_id,
|
|
compte_id,
|
|
mois_activite,
|
|
date_debut,
|
|
date_fin,
|
|
mois_paie,
|
|
date_paie,
|
|
sum(heures_contrat) as heures_contrat,
|
|
sum(heures_payees) as heures_payees,
|
|
sum(heures_travaillees) as heures_travaillees,
|
|
--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 w_cible_1
|
|
GROUP BY 1,2,3,4,5,6,7,8,9,10,11
|
|
;
|
|
|
|
DROP TABLE IF EXISTS w_tmp
|
|
;
|
|
|
|
CREATE TEMP TABLE w_tmp AS
|
|
SELECT
|
|
cti_bul,
|
|
rownum,
|
|
salarie_id,
|
|
contrat_id,
|
|
contrat_mois_id,
|
|
compte_id,
|
|
mois_paie,
|
|
min(mois_activite) as mois_activite,
|
|
min(date_debut) as date_debut,
|
|
max(date_fin) as date_fin,
|
|
max(date_paie) as date_paie,
|
|
sum(heures_contrat) as heures_contrat,
|
|
sum(heures_payees) as heures_payees,
|
|
sum(heures_travaillees) as heures_travaillees,
|
|
--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 w_hp_4
|
|
GROUP BY 1,2,3,4,5,6,7
|
|
;
|
|
|
|
-- Inserer pour chaque bulletin une ligne 'Ecart cumulé' qui va faire le compte avec le total
|
|
INSERT INTO rh.p_historique_paie(
|
|
salarie_id,
|
|
contrat_id,
|
|
contrat_mois_id,
|
|
mois_activite,
|
|
date_debut,
|
|
date_fin,
|
|
mois_paie,
|
|
date_paie,
|
|
rubrique_id,
|
|
compte_id,
|
|
organisme_cotisation_id,
|
|
base,
|
|
nombre,
|
|
heure_contrat,
|
|
heure_payee,
|
|
heure_travaillee,
|
|
montant_masse_salariale,
|
|
montant_brut,
|
|
montant_avantage_nature,
|
|
montant_frais_imposables,
|
|
taux_cotisation_salarie,
|
|
montant_cotisation_salarie,
|
|
taux_cotisation_patronale,
|
|
montant_cotisation_patronale,
|
|
montant_od_net_salarie,
|
|
montant_od_net_patronale,
|
|
montant_net_imposable_salarie,
|
|
montant_net_a_payer_salarie)
|
|
SELECT
|
|
subq.salarie_id,
|
|
subq.contrat_id,
|
|
subq.contrat_mois_id,
|
|
subq.mois_activite,
|
|
subq.date_debut,
|
|
subq.date_fin,
|
|
subq.mois_paie,
|
|
subq.date_paie,
|
|
(select oid from rh.t_rubriques where code_original = 'C000'),
|
|
subq.compte_id,
|
|
0 as organisme_cotisation_id,
|
|
0 as base,
|
|
0 as nombre,
|
|
subq.heures_contrat,
|
|
subq.heures_payees,
|
|
subq.heures_travaillees,
|
|
0 as montant_masse_salariale,
|
|
subq.montant_brut,
|
|
subq.montant_avantage_nature,
|
|
subq.montant_frais_imposables,
|
|
0 as taux_cotisation_salarie,
|
|
subq.montant_cotisation_salarie,
|
|
0 as taux_cotisation_patronale,
|
|
subq.montant_cotisation_patronale,
|
|
subq.montant_od_net_salarie,
|
|
subq.montant_od_net_patronale,
|
|
subq.montant_net_imposable_salarie,
|
|
subq.montant_net_a_payer_salarie
|
|
FROM (
|
|
SELECT
|
|
coalesce(w_cible.salarie_id, w_tmp.salarie_id) as salarie_id,
|
|
coalesce(w_cible.contrat_id, w_tmp.contrat_id) as contrat_id,
|
|
coalesce(w_cible.contrat_mois_id, w_tmp.contrat_mois_id) as contrat_mois_id,
|
|
coalesce(w_cible.compte_id, w_tmp.compte_id) as compte_id,
|
|
coalesce(w_cible.cti_bul, w_tmp.cti_bul) as cti_bul,
|
|
coalesce(w_cible.mois_activite, w_tmp.mois_activite) as mois_activite,
|
|
coalesce(w_cible.date_debut, w_tmp.date_debut) as date_debut,
|
|
coalesce(w_cible.date_fin, w_tmp.date_fin) as date_fin,
|
|
coalesce(w_cible.mois_paie, w_tmp.mois_paie) as mois_paie,
|
|
coalesce(w_cible.date_paie, w_tmp.date_paie) as date_paie,
|
|
-- sum(coalesce(w_cible.heures_contrat, 0) - coalesce(w_tmp.heures_contrat, 0)) AS heures_contrat,
|
|
0 as heures_contrat,
|
|
sum(coalesce(w_cible.heures_payees, 0) - coalesce(w_tmp.heures_payees, 0)) AS heures_payees,
|
|
sum(coalesce(w_cible.heures_travaillees, 0) - coalesce(w_tmp.heures_travaillees, 0)) AS heures_travaillees,
|
|
sum(coalesce(w_cible.montant_brut, 0) - coalesce(w_tmp.montant_brut, 0)) AS montant_brut,
|
|
sum(coalesce(w_cible.montant_avantage_nature, 0) - coalesce(w_tmp.montant_avantage_nature, 0)) AS montant_avantage_nature,
|
|
sum(coalesce(w_cible.montant_frais_imposables, 0) - coalesce(w_tmp.montant_frais_imposables, 0)) AS montant_frais_imposables,
|
|
sum(coalesce(w_cible.montant_cotisation_salarie, 0) - coalesce(w_tmp.montant_cotisation_salarie, 0)) AS montant_cotisation_salarie,
|
|
sum(coalesce(w_cible.montant_cotisation_patronale, 0) - coalesce(w_tmp.montant_cotisation_patronale, 0)) AS montant_cotisation_patronale,
|
|
sum(coalesce(w_cible.montant_od_net_salarie, 0) - coalesce(w_tmp.montant_od_net_salarie, 0)) AS montant_od_net_salarie,
|
|
sum(coalesce(w_cible.montant_od_net_patronale, 0) - coalesce(w_tmp.montant_od_net_patronale, 0)) AS montant_od_net_patronale,
|
|
sum(coalesce(w_cible.montant_net_imposable_salarie, 0) - coalesce(w_tmp.montant_net_imposable_salarie, 0)) AS montant_net_imposable_salarie,
|
|
sum(coalesce(w_cible.montant_net_a_payer_salarie, 0) - coalesce(w_tmp.montant_net_a_payer_salarie, 0)) AS montant_net_a_payer_salarie
|
|
FROM (select cti_bul, rownum, mois_paie from w_tmp
|
|
union
|
|
select cti_bul, rownum, mois_paie from w_cible_2) as all_buls
|
|
left JOIN w_tmp ON true
|
|
and w_tmp.cti_bul = all_buls.cti_bul
|
|
and w_tmp.rownum = all_buls.rownum
|
|
and w_tmp.mois_paie = all_buls.mois_paie
|
|
left JOIN w_cible_2 as w_cible ON true
|
|
and w_cible.cti_bul = all_buls.cti_bul
|
|
and w_cible.rownum = all_buls.rownum
|
|
and w_cible.mois_paie = all_buls.mois_paie
|
|
GROUP BY 1,2,3,4,5,6,7,8,9,10) AS subq
|
|
WHERE 1!=1
|
|
OR subq.heures_contrat != 0
|
|
OR subq.heures_payees != 0
|
|
OR subq.heures_travaillees != 0
|
|
OR subq.montant_brut != 0
|
|
OR subq.montant_avantage_nature != 0
|
|
OR subq.montant_frais_imposables != 0
|
|
OR subq.montant_cotisation_salarie != 0
|
|
OR subq.montant_cotisation_patronale != 0
|
|
OR subq.montant_od_net_salarie != 0
|
|
OR subq.montant_od_net_patronale != 0
|
|
OR subq.montant_net_imposable_salarie != 0
|
|
OR subq.montant_net_a_payer_salarie != 0
|
|
;
|
|
|
|
]]></sqlcmd>
|
|
</NODE>
|
|
<NODE label="Ventilation des profils">
|
|
<sqlcmd><![CDATA[
|
|
|
|
-- Alimentation des profils simultanés.
|
|
TRUNCATE rh.p_profil_contrat_mois
|
|
;
|
|
|
|
INSERT INTO rh.p_profil_contrat_mois (
|
|
profil_id,
|
|
contrat_mois_id,
|
|
salarie_id,
|
|
ratio,
|
|
mois)
|
|
SELECT
|
|
coalesce(w_profils.profil_id, 0) AS profil_id,
|
|
p_contrats_mois.oid AS contrat_mois_id,
|
|
p_contrats_mois.salarie_id,
|
|
1 AS ratio,
|
|
p_contrats_mois.mois_activite
|
|
FROM rh.p_contrats_mois
|
|
JOIN rh.p_salaries ON p_salaries.oid = p_contrats_mois.salarie_id
|
|
JOIN w_profils ON 1=1
|
|
AND w_profils.mat = p_salaries.code_original
|
|
AND w_profils.date_debut = p_contrats_mois.date_debut
|
|
AND w_profils.date_fin = p_contrats_mois.date_fin
|
|
GROUP BY 1,2,3,4,5
|
|
;
|
|
|
|
]]></sqlcmd>
|
|
</NODE>
|
|
<NODE label="Arrêts de travail">
|
|
<sqlcmd><![CDATA[
|
|
|
|
]]></sqlcmd>
|
|
</NODE>
|
|
<NODE label="Visites Médicales">
|
|
<sqlcmd><![CDATA[
|
|
|
|
]]></sqlcmd>
|
|
</NODE>
|
|
<NODE label="Accidents du travail">
|
|
<sqlcmd><![CDATA[
|
|
|
|
]]></sqlcmd>
|
|
</NODE>
|
|
<NODE label="Formations">
|
|
<sqlcmd><![CDATA[
|
|
|
|
]]></sqlcmd>
|
|
</NODE>
|
|
<NODE label="Handicap">
|
|
<sqlcmd><![CDATA[
|
|
|
|
]]></sqlcmd>
|
|
</NODE>
|
|
</NODE>
|
|
<NODE name="POST" label="POST-TRAITEMENTS">
|
|
<NODE name="DIVERS" type="common"/>
|
|
<NODE label="Mise à jour de la table Divers (mois en cours)">
|
|
<sqlcmd><![CDATA[
|
|
|
|
-- Màj du mois non clôturé.
|
|
-- DELETE FROM rh.t_divers
|
|
-- WHERE code = 'MOIS_EN_COURS'
|
|
-- ;
|
|
|
|
-- INSERT INTO rh.t_divers(
|
|
-- code,
|
|
-- texte,
|
|
-- valeur,
|
|
-- valeur_date,
|
|
-- description)
|
|
-- VALUES(
|
|
-- 'MOIS_EN_COURS',
|
|
-- 'Mois en cours (non clôturé).',
|
|
-- (SELECT to_char(date_paie_encours, 'YYYYMM') FROM w_periode),
|
|
-- (SELECT date_paie_encours FROM w_periode),
|
|
-- 'Mois en cours (non clôturé).'
|
|
-- )
|
|
-- ;
|
|
|
|
]]></sqlcmd>
|
|
</NODE>
|
|
<NODE name="POST" type="common"/>
|
|
</NODE>
|
|
<NODE name="VACUUM" label="REORGANISATION BASE DE DONNEES">
|
|
<NODE name="VACUUM" type="common" />
|
|
</NODE>
|
|
<NODE name="RAZ" label="RAZ BASE">
|
|
<NODE name="RAZ" type="common" />
|
|
</NODE>
|
|
<NODE name="RAZ_ALL" label="RAZ ALL">
|
|
<NODE name="RAZ_ALL" type="common" />
|
|
</NODE>
|
|
</ROOT>
|