temp.x_) *
************/
-- Création d'une table temp des établissements pour faciliter les futures jointures.
DROP TABLE IF EXISTS w_ets
;
CREATE TEMP TABLE w_ets AS
SELECT
societe.idsociete,
societe.codsociete,
etablissements.codetab,
MAX(numsiren) as siren,
MAX(numsiren||nic) as siret,
MAX(nomsociete) as nomsociete,
MAX(nometab) as nometab
FROM prod_pegase.etablissements
JOIN prod_pegase.societe ON societe.idsociete = etablissements.idsociete
WHERE 1=1
and nullif(trim(etablissements.codetab), '') is not null
and (1!=1
OR numsiren IN (SELECT rhp_in('siren')) -- Soit un ou plusieurs SIREN ont été défini,
OR numsiren||nic IN (SELECT rhp_in('siren')) -- et/ou soit un ou plusieurs SIRET,
OR societe.codsociete IN (SELECT rhp_in('siren')) -- et/ou soit un ou plusieurs codes entreprise.
OR etablissements.codetab IN (SELECT rhp_in('siren'))) -- et/ou soit un ou plusieurs codes établissement.
GROUP BY 1,2,3
;
-- Identification des Entreprises.
DROP TABLE IF EXISTS temp.x_ref_ent
;
CREATE TABLE temp.x_ref_ent AS
SELECT
idsociete as code_original,
codsociete as code,
MAX(nomsociete) as texte,
MAX(siren) as siren,
null::text as texte_court
FROM w_ets
GROUP BY 1,2
;
-- Identification des Etablissements.
DROP TABLE IF EXISTS temp.x_ref_ets
;
CREATE TABLE temp.x_ref_ets AS
SELECT
idsociete as ent_code_original,
idsociete||'-'||codetab as ety_code_original,
codetab as code_original,
codetab as code,
MAX(siret) as siret,
MAX(nometab) as texte,
null::text as texte_court
FROM w_ets
GROUP BY 1,2,3,4
;
]]>
= to_char(rhp('rhprovider_start')::date, 'YYYYMM')
and (codexercice <> '' or codperiode <> '')
;
DROP TABLE IF EXISTS temp.x_hst_bulletin
;
CREATE TABLE temp.x_hst_bulletin AS
SELECT
w_bul.ent_code_original,
w_bul.ets_code_original,
w_bul.ent_code_original||'-'||w_bul.ets_code_original as ety_code_original,
w_bul.sal_code_original,
w_bul.bul_code_original,
w_bul.date_debut,
w_bul.date_fin,
w_bul.date_fin as date_paie,
w_bul.mois_paie,
row_number() over () as row_id,
row_number() over (order by ent_code_original, ets_code_original, sal_code_original, bul_code_original) as bul_id,
null::text as cnt_code_original, -- un bulletin est rattaché à un seul et unique contrat.
0 as est_hors_periode
from w_bul
;
-- Association avec le contrat correspondant aux dates.
-- Un bulletin est rattaché à un seul et unique contrat.
with toto as (
SELECT
x_hst_bulletin.row_id,
(max(array[x_hst_contrat.date_fin::text, x_hst_contrat.cnt_code_original]))[2] as cnt_code_original
from temp.x_hst_bulletin
join temp.x_hst_contrat on 1=1
and x_hst_contrat.sal_code_original = x_hst_bulletin.sal_code_original
and base.cti_overlaps(x_hst_contrat.date_debut, x_hst_contrat.date_fin, x_hst_bulletin.date_debut, x_hst_bulletin.date_fin)
group by 1
)
UPDATE temp.x_hst_bulletin set
cnt_code_original = toto.cnt_code_original
from toto
where x_hst_bulletin.row_id = toto.row_id
;
-- Association avec le contrat précédent.
with toto as (
SELECT
x_hst_bulletin.row_id,
(max(array[x_hst_contrat.date_fin::text, x_hst_contrat.cnt_code_original]))[2] as cnt_code_original
from temp.x_hst_bulletin
join temp.x_hst_contrat on 1=1
and x_hst_contrat.sal_code_original = x_hst_bulletin.sal_code_original
and x_hst_contrat.date_fin < x_hst_bulletin.date_debut
where x_hst_bulletin.cnt_code_original is null
group by 1
)
UPDATE temp.x_hst_bulletin set
cnt_code_original = toto.cnt_code_original,
est_hors_periode = 1
from toto
where x_hst_bulletin.row_id = toto.row_id
;
-- Association avec le contrat suivant.
with toto as (
SELECT
x_hst_bulletin.row_id,
(max(array[x_hst_contrat.date_fin::text, x_hst_contrat.cnt_code_original]))[2] as cnt_code_original
from temp.x_hst_bulletin
join temp.x_hst_contrat on 1=1
and x_hst_contrat.sal_code_original = x_hst_bulletin.sal_code_original
and x_hst_contrat.date_fin > x_hst_bulletin.date_debut
where x_hst_bulletin.cnt_code_original is null
group by 1
)
UPDATE temp.x_hst_bulletin set
cnt_code_original = toto.cnt_code_original,
est_hors_periode = 1
from toto
where x_hst_bulletin.row_id = toto.row_id
;
-- ICI : Tous les bulletins doivent avoir un contrat de renseigné.
-- A remonter plus tard dans une table spéciale avant suppression pour controle expert.
delete from temp.x_hst_bulletin
where cnt_code_original is null
;
-- La date min du premier contrat et/ou du premier bulletin détermine le début de la ventilation du salarié.
DROP TABLE IF EXISTS w_lim_sal
;
CREATE TEMP TABLE w_lim_sal AS
with toto as (
select
sal_code_original,
min(date_debut) as date_debut,
max(case when date_fin = '2099-12-31'::date then base.cti_last_day(current_date) else date_fin end) as date_fin
from temp.x_hst_contrat
group by 1
union all
select
sal_code_original,
min(date_debut) as date_debut,
max(case when date_fin = '2099-12-31'::date then base.cti_last_day(current_date) else date_fin end) as date_fin
from temp.x_hst_bulletin
group by 1
)
select
sal_code_original,
min(date_debut) as date_debut,
to_char(min(date_debut), 'YYYYMM')::int as mois_debut,
max(date_fin) as date_fin,
to_char(max(date_fin), 'YYYYMM')::int as mois_fin
from toto
group by 1
;
-- HISTORIQUE ETP Théorique contrat.
DROP TABLE IF EXISTS temp.x_hst_etp_contrat
;
CREATE TABLE temp.x_hst_etp_contrat AS
SELECT
w_evo.ent_code_original||'-'||w_evo.ets_code_original as ety_code_original,
w_evo.sal_code_original,
w_evo.cnt_code_original,
greatest(w_evo.sal_date_debut, w_evo.cnt_date_debut, w_lim_sal.date_debut) as date_effet,
w_evo.etp_contrat
from w_evo
join w_lim_sal on w_lim_sal.sal_code_original = w_evo.sal_code_original
;
-- HISTORIQUE CSP.
DROP TABLE IF EXISTS temp.x_hst_categorie_socio_professionnelle
;
CREATE TABLE temp.x_hst_categorie_socio_professionnelle AS
SELECT
w_evo.ent_code_original||'-'||w_evo.ets_code_original as ety_code_original,
w_evo.sal_code_original,
w_evo.cnt_code_original,
greatest(w_evo.sal_date_debut, w_evo.cnt_date_debut, w_lim_sal.date_debut) as date_effet,
w_evo.codinseeemploi2003 as categorie_socio_professionnelle_code_original
from w_evo
join w_lim_sal on w_lim_sal.sal_code_original = w_evo.sal_code_original
;
-- HISTORIQUE Motif de début.
DROP TABLE IF EXISTS temp.x_hst_motif_debut_contrat
;
CREATE TABLE temp.x_hst_motif_debut_contrat AS
SELECT
w_evo.ent_code_original||'-'||w_evo.ets_code_original as ety_code_original,
w_evo.sal_code_original,
w_evo.cnt_code_original,
greatest(w_evo.sal_date_debut, w_evo.cnt_date_debut, w_lim_sal.date_debut) as date_effet,
w_evo.motif_debut as motif_debut_code_original
from w_evo
join w_lim_sal on w_lim_sal.sal_code_original = w_evo.sal_code_original
;
-- HISTORIQUE Motif de fin.
DROP TABLE IF EXISTS temp.x_hst_motif_fin_contrat
;
CREATE TABLE temp.x_hst_motif_fin_contrat AS
SELECT
w_evo.ent_code_original||'-'||w_evo.ets_code_original as ety_code_original,
w_evo.sal_code_original,
w_evo.cnt_code_original,
greatest(w_evo.sal_date_debut, w_evo.cnt_date_debut, w_lim_sal.date_debut) as date_effet,
w_evo.motif_fin as motif_fin_code_original
from w_evo
join w_lim_sal on w_lim_sal.sal_code_original = w_evo.sal_code_original
;
-- HISTORIQUE Types de contrat.
DROP TABLE IF EXISTS temp.x_hst_type_contrat
;
CREATE TABLE temp.x_hst_type_contrat AS
SELECT
w_evo.ent_code_original||'-'||w_evo.ets_code_original as ety_code_original,
w_evo.sal_code_original,
w_evo.cnt_code_original,
greatest(w_evo.sal_date_debut, w_evo.cnt_date_debut, w_lim_sal.date_debut) as date_effet,
w_evo.typcontrat as type_contrat_code_original
from w_evo
join w_lim_sal on w_lim_sal.sal_code_original = w_evo.sal_code_original
;
-- -- HISTORIQUE CSP.
-- DROP TABLE IF EXISTS temp.x_hst_organisme_cotisation
-- ;
-- CREATE TABLE temp.x_hst_organisme_cotisation AS
-- SELECT
-- w_cnt.ent_code_original||'-'||w_cnt.ets_code_original as ety_code_original,
-- w_cnt.sal_code_original,
-- w_cnt.cnt_code_original,
-- greatest(w_cnt.date_debut, w_lim_sal.date_debut) as date_effet,
-- w_cnt.codinseeemploi2003 as categorie_socio_professionnelle_code_original
-- from w_cnt
-- join w_lim_sal on w_lim_sal.sal_code_original = w_cnt.sal_code_original
-- ;
-- HISTORIQUE CSP.
DROP TABLE IF EXISTS temp.x_hst_qualification
;
CREATE TABLE temp.x_hst_qualification AS
SELECT
w_evo.ent_code_original||'-'||w_evo.ets_code_original as ety_code_original,
w_evo.sal_code_original,
w_evo.cnt_code_original,
greatest(w_evo.sal_date_debut, w_evo.cnt_date_debut, w_lim_sal.date_debut) as date_effet,
w_evo.emploi as qualification_code_original
from w_evo
join w_lim_sal on w_lim_sal.sal_code_original = w_evo.sal_code_original
;
-- HISTORIQUE CSP.
DROP TABLE IF EXISTS temp.x_hst_statut
;
CREATE TABLE temp.x_hst_statut AS
SELECT
w_evo.ent_code_original||'-'||w_evo.ets_code_original as ety_code_original,
w_evo.sal_code_original,
w_evo.cnt_code_original,
greatest(w_evo.sal_date_debut, w_evo.cnt_date_debut, w_lim_sal.date_debut) as date_effet,
w_evo.codcategorie as statut_code_original
from w_evo
join w_lim_sal on w_lim_sal.sal_code_original = w_evo.sal_code_original
;
-- HISTORIQUE CSP.
DROP TABLE IF EXISTS temp.x_hst_type_temps_travail
;
CREATE TABLE temp.x_hst_type_temps_travail AS
SELECT
w_evo.ent_code_original||'-'||w_evo.ets_code_original as ety_code_original,
w_evo.sal_code_original,
w_evo.cnt_code_original,
greatest(w_evo.sal_date_debut, w_evo.cnt_date_debut, w_lim_sal.date_debut) as date_effet,
w_evo.code_ttt as type_temps_travail_code_original
from w_evo
join w_lim_sal on w_lim_sal.sal_code_original = w_evo.sal_code_original
;
-- HISTORIQUE CSP.
DROP TABLE IF EXISTS temp.x_hst_service
;
CREATE TABLE temp.x_hst_service AS
SELECT
w_evo.ent_code_original||'-'||w_evo.ets_code_original as ety_code_original,
w_evo.sal_code_original,
w_evo.cnt_code_original,
greatest(w_evo.sal_date_debut, w_evo.cnt_date_debut, w_lim_sal.date_debut) as date_effet,
w_evo.codsection as service_code_original
from w_evo
join w_lim_sal on w_lim_sal.sal_code_original = w_evo.sal_code_original
;
-- HISTORIQUE CSP.
DROP TABLE IF EXISTS temp.x_hst_code_emploi
;
CREATE TABLE temp.x_hst_code_emploi AS
SELECT
w_evo.ent_code_original||'-'||w_evo.ets_code_original as ety_code_original,
w_evo.sal_code_original,
w_evo.cnt_code_original,
greatest(w_evo.sal_date_debut, w_evo.cnt_date_debut, w_lim_sal.date_debut) as date_effet,
w_evo.emploi as code_emploi_code_original
from w_evo
join w_lim_sal on w_lim_sal.sal_code_original = w_evo.sal_code_original
;
-- HISTORIQUE GRILLE.
DROP TABLE IF EXISTS temp.x_hst_grille
;
CREATE TABLE temp.x_hst_grille AS
SELECT
w_evo.ent_code_original||'-'||w_evo.ets_code_original as ety_code_original,
w_evo.sal_code_original,
w_evo.cnt_code_original,
greatest(w_evo.sal_date_debut, w_evo.cnt_date_debut, w_lim_sal.date_debut) as date_effet,
w_evo.champslibres as grille_code_original
from w_evo
join w_lim_sal on w_lim_sal.sal_code_original = w_evo.sal_code_original
;
]]>
= to_char(rhp('rhprovider_start')::date, 'YYYYMM')
) as suqb)
select
bulletins.bul_id,
bulletins.ety_code_original,
bulletins.sal_code_original,
bulletins.cnt_code_original,
bulletins.bul_code_original,
bulletins.date_debut,
bulletins.date_fin,
bulletins.mois_paie as mois_activite,
bulletins.date_paie,
bulletins.mois_paie,
codrubrique as rub_code_original,
coalesce(nullif(eubasapc, ''), '0')::numeric as base,
coalesce(nullif(eutausalapc, ''), '0')::numeric as txsal,
coalesce(nullif(eumntsalapc, ''), '0')::numeric as mntsal,
coalesce(nullif(eutaupatapc, ''), '0')::numeric as txpat,
coalesce(nullif(eumntpatapc, ''), '0')::numeric as mntpat
from temp.x_hst_bulletin as bulletins
join temp.x_ref_ets on x_ref_ets.ety_code_original = bulletins.ety_code_original
join prod_pegase.bulletinsdetail on 1=1
and bulletinsdetail.idsociete = bulletins.ent_code_original
and bulletinsdetail.codetab = bulletins.ets_code_original
and bulletinsdetail.codsalarie = bulletins.sal_code_original
and (bulletinsdetail.codexercice||bulletinsdetail.codbulletin)::text = bulletins.bul_code_original
where 1=1
AND bulletins.mois_paie >= to_char(rhp('rhprovider_start')::date, 'YYYYMM')
AND (1!=1
or eumntsalapc != ''
or eumntpatapc != ''
or eubasapc != '')
UNION ALL
select
bul_id,
ety_code_original,
sal_code_original,
cnt_code_original,
bul_code_original,
date_debut,
date_fin,
mois_paie as mois_activite,
date_paie,
mois_paie,
rub as rub_code_original,
case when rub in ('C001', 'C002', 'C009') then val::numeric else 0::numeric end as base,
0 as txsal,
case
when rub in ('C003', 'C004', 'C008') then val::numeric
when rub = 'C007' then -val::numeric
else 0::numeric end as mnt_sal,
0 as txpat,
case when rub = 'C006' then val::numeric else 0::numeric end as mnt_pat
from w_cum
;
-- #specifique Forfaits Jours & Vacations (on renseigne dans base le nombre d'heures contractuel d'après le champ "heures reconstituées").
with liste_rub_fj as (
select t_rubriques.code_original
from rh.t_listes
join rh.t_listes_contenu on t_listes_contenu.liste_id = t_listes.oid
join rh.t_rubriques on t_rubriques.oid = t_listes_contenu.to_id
where t_listes.code = 'CTI_PEGASE_FTJ'
)
, fj_sal as (
select
bul_id,
sal_code_original
from temp.x_hst_paie
where true
and rub_code_original in (select code_original from liste_rub_fj)
and base = 0
)
, sal_etp as (
select
x_hst_etp_contrat.ety_code_original,
x_hst_etp_contrat.sal_code_original,
date_effet as date_debut,
lead(date_effet - 1, 1, '2099-12-31'::date) over w as date_fin,
etp_contrat
from temp.x_hst_etp_contrat
join fj_sal on fj_sal.sal_code_original = x_hst_etp_contrat.sal_code_original
group by 1,2,3 ,5
window w as (partition by x_hst_etp_contrat.sal_code_original order by date_effet)
)
, new_data_fj as (
select
x_hst_paie.bul_id,
coalesce(etp_contrat, 1.0) * x_hst_paie.base as base
from temp.x_hst_paie
join fj_sal on fj_sal.bul_id = x_hst_paie.bul_id
join sal_etp on 1=1
and sal_etp.ety_code_original = x_hst_paie.ety_code_original
and sal_etp.sal_code_original = x_hst_paie.sal_code_original
and x_hst_paie.date_paie between sal_etp.date_debut and sal_etp.date_fin
where 1=1
and x_hst_paie.rub_code_original = 'C009')
update temp.x_hst_paie set
base = new_data_fj.base
from new_data_fj
where 1=1
and new_data_fj.bul_id = x_hst_paie.bul_id
and x_hst_paie.rub_code_original in (select code_original from liste_rub_fj)
;
-- Alimentation de la base de la rubrique forfait jour à partir de la base d'une rubrique référence avec la condition de nombre de jour pour définir les temps pleins et affecter les heures contrat
with parametrage_pegase_forfait_jour as (
select
valeur
,split_part(valeur, '|', 1) as rubrique_ref -- rubrique source
,split_part(valeur, '|', 2) as rubrique_cible -- rubrique cible
,split_part(valeur, '|', 3)::int as max_jour -- valeur de condition du nombre de jour maximum à prendre en compte pour distinguer les temps complets des temps partiels
from rh.t_divers
where code = 'PEGASE_FORFAIT_JOUR'
)
, forfait_cadre as (
select
sal_code_original,
mois_paie,
base,
bul_id
from temp.x_hst_paie
where rub_code_original in (select rubrique_ref from parametrage_pegase_forfait_jour)
)
, modif_base as (
select
x_hst_paie.sal_code_original as sal_code_original,
x_hst_paie.mois_paie as mois_paie,
x_hst_paie.base,
x_hst_paie.rub_code_original,
forfait_cadre.bul_id as bul_id,
case when forfait_cadre.base < (select max_jour from parametrage_pegase_forfait_jour) then forfait_cadre.base*7 else 151.67 end as forfait_jour_base -- si le nombre de jour (rubrique source) est inférieur au nombre de jour max défini alors on multiplie la base de la rubrique source par 7 et on affecte cette valeur à la rubrique cible sinon on affecte 151,7 (temps plein)
from temp.x_hst_paie
join forfait_cadre on forfait_cadre.sal_code_original = x_hst_paie.sal_code_original and forfait_cadre.mois_paie = x_hst_paie.mois_paie and forfait_cadre.bul_id = x_hst_paie.bul_id
where x_hst_paie.rub_code_original in (select rubrique_cible from parametrage_pegase_forfait_jour)
and (select valeur from parametrage_pegase_forfait_jour) is not null and (select valeur from parametrage_pegase_forfait_jour) <> ''
)
update temp.x_hst_paie set
base = modif_base.forfait_jour_base
from modif_base
where 1=1
and x_hst_paie.sal_code_original = modif_base.sal_code_original
and x_hst_paie.mois_paie = modif_base.mois_paie
and x_hst_paie.bul_id = modif_base.bul_id
and x_hst_paie.base is distinct from modif_base.forfait_jour_base
and x_hst_paie.rub_code_original in (select rubrique_cible from parametrage_pegase_forfait_jour)
;
]]>