You can not select more than 25 topics Topics must start with a letter or number, can include dashes ('-') and can be up to 35 characters long.
 
 
 

1589 lines
73 KiB

<?xml version="1.0" encoding="ISO-8859-1"?>
<ROOT>
<NODE name="INIT" label="INITIALISATIONS">
<NODE name="INIT" type="common" />
<NODE label="Mise à jour des informations permanentes">
<sqlcmd><![CDATA[
-- NON EXTRAIT DE CEGIALPHA :
-- * FNP_PPA_BUL_POT_ANNEES_HIST_D ; peut-être utile...
-- * FNP_PPA_CTA_JOURNAUX ; Analytique comptable...
DROP TABLE IF EXISTS w_ets
;
CREATE TEMP TABLE w_ets AS
select
-1 as entreprise_id,
-1 as etablissement_id,
siren,
siren||nic as siret,
libelle,
code_dossier,
fnp_tab_dos_dossiers.cpte_structure
from prod_cegialpha.fnp_tab_siret
join prod_cegialpha.fnp_tab_siret_ets on fnp_tab_siret_ets.cpte_siret = fnp_tab_siret.cpt_siret
join prod_cegialpha.fnp_tab_dos_dossiers on fnp_tab_dos_dossiers.cpte_structure = fnp_tab_siret_ets.cpte_structure
-- WHERE siren = rhp('siren')
;
-- Màj des Entreprises
INSERT INTO rh.t_entreprises(code_original, code, texte, texte_court)
SELECT siren, siren, libelle, substr(libelle, 1, 50)
FROM w_ets
WHERE siren NOT IN (SELECT code_original FROM rh.t_entreprises)
;
-- Màj des Etablissements
INSERT INTO rh.t_etablissements(code_original, code, texte, texte_court, entreprise_id)
SELECT siret, siret, libelle, substr(libelle, 1, 50), t_entreprises.oid
FROM w_ets
JOIN rh.t_entreprises ON t_entreprises.code_original = w_ets.siren
WHERE siret NOT IN (SELECT code_original FROM rh.t_etablissements)
;
UPDATE w_ets SET
entreprise_id = t_etablissements.oid,
etablissement_id = t_etablissements.entreprise_id
FROM rh.t_etablissements
WHERE w_ets.siret = t_etablissements.code_original
;
-- Màj des catégories socio-professionnelles
INSERT INTO rh.t_categories_socio_professionnelle(code_original, code, texte, texte_court)
SELECT lower(substr(code_valeur, 1, 4)), lower(substr(code_valeur, 1, 4)), libelle, substr(libelle, 1, 50)
FROM prod_cegialpha.fnp_dic_csp_categ_socio_prof
WHERE 1=1
AND lower(substr(code_valeur, 1, 4)) NOT IN (SELECT code_original FROM rh.t_categories_socio_professionnelle)
GROUP BY 1,2,3,4
;
-- Màj des groupes cotisants.
INSERT INTO rh.t_groupes_cotisant(code_original, code, texte, texte_court)
SELECT cpt_groupe, code_groupe, libelle, substr(libelle, 1, 50)
FROM prod_cegialpha.fnp_tab_emp_grp_coc
WHERE cpt_groupe NOT IN (SELECT code_original FROM rh.t_groupes_cotisant)
GROUP BY 1,2,3,4
;
-- Màj des motifs de début de contrat -- fnp_dic_ctr_motifs_entrees ou fnp_sys_dad_motifs_debut (ce dernier est mieux renseigné).
INSERT INTO rh.t_motifs_debut_contrat(code_original, code, texte, texte_court)
SELECT code_valeur, code_valeur, libelle, substr(libelle, 1, 50)
FROM prod_cegialpha.fnp_sys_dad_motifs_debut
WHERE code_valeur NOT IN (SELECT code_original FROM rh.t_motifs_debut_contrat)
;
-- Màj des motifs de fin de contrat -- fnp_dic_ctr_motifs_sorties ou fnp_sys_dad_motifs_fin (ce dernier est mieux renseigné).
INSERT INTO rh.t_motifs_fin_contrat(code_original, code, texte, texte_court)
SELECT code_valeur, code_valeur, libelle, substr(libelle, 1, 50)
FROM prod_cegialpha.fnp_sys_dad_motifs_fin
WHERE code_valeur NOT IN (SELECT code_original FROM rh.t_motifs_fin_contrat)
;
-- Màj des nationalités
INSERT INTO rh.t_nationalites(code_original, code, texte, texte_court)
SELECT code_valeur, code_valeur, libelle, substr(libelle, 1, 50)
FROM prod_cegialpha.fnp_dic_per_nationalites
WHERE code_valeur NOT IN (SELECT code_original FROM rh.t_nationalites)
GROUP BY 1,2,3,4
;
-- Màj des organismes de cotisation
INSERT INTO rh.t_organismes_cotisation(code_original, code, texte, texte_court)
SELECT cpt_organisme, identifiant_organisme, raison_sociale, substr(raison_sociale, 1, 50)
FROM prod_cegialpha.fnp_tab_org_organismes
WHERE cpt_organisme NOT IN (SELECT code_original FROM rh.t_organismes_cotisation)
GROUP BY 1,2,3,4
;
-- Màj des qualifications
INSERT INTO rh.t_qualifications(code_original, code, texte, texte_court)
SELECT cpt_qualification, code_qualification, libelle, substr(libelle, 1, 50)
FROM prod_cegialpha.fnp_tab_emp_qua_coc
WHERE cpt_qualification NOT IN (SELECT code_original FROM rh.t_qualifications)
;
-- Màj des rubriques
INSERT INTO rh.t_rubriques(code_original, code, texte, texte_court, rang_edition)
SELECT cpt_rubrique, identifiant_rubrique, libelle, substr(libelle, 1, 50), identifiant_rubrique::int
FROM prod_cegialpha.fnp_ppa_rub_rubriques
WHERE cpt_rubrique NOT IN (SELECT code_original FROM rh.t_rubriques)
;
-- Rubrique C000 est créée dans le SHARE.
-- Màj des situations de famille
INSERT INTO rh.t_situations_famille(code_original, code, texte, texte_court)
SELECT code_valeur, code_valeur, libelle, substr(libelle, 1, 50)
FROM prod_cegialpha.fnp_dic_per_situations_famil
WHERE code_valeur NOT IN (SELECT code_original FROM rh.t_situations_famille)
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 code_valeur, code_valeur, libelle, substr(libelle, 1, 50)
FROM prod_cegialpha.fnp_dic_ctr_types_contrats
WHERE code_valeur NOT IN (SELECT code_original FROM rh.t_types_contrat)
;
-- Màj des statuts -- fnp_dic_ata_niveaux_qualif ou fnp_sys_dad_status_prof
INSERT INTO rh.t_statuts(code_original, code, texte, texte_court)
SELECT code_valeur, code_valeur, libelle, substr(libelle, 1, 50)
FROM prod_cegialpha.fnp_sys_dad_status_prof
WHERE code_valeur NOT IN (SELECT code_original FROM rh.t_statuts)
;
-- Màj des types de temps de travail
INSERT INTO rh.t_types_temps_travail(code_original, code, texte, texte_court)
with w_ttt as (
select
round(fnp_tab_ctr_contrats_avenants.horaire_contractuel*100/fnp_tab_gtp_horaires.horaire_hebdo) as pct
from prod_cegialpha.fnp_tab_ctr_contrats_avenants
join prod_cegialpha.fnp_tab_str_horaires on fnp_tab_str_horaires.cpte_structure=fnp_tab_ctr_contrats_avenants.cpte_ets_reference
join prod_cegialpha.fnp_tab_gtp_horaires on 1=1
and fnp_tab_gtp_horaires.cpt_horaire=fnp_tab_str_horaires.cpte_horaire
and fnp_tab_gtp_horaires.cpt_horaire=fnp_tab_ctr_contrats_avenants.cpte_horaire_ref
group by 1)
select
case when pct = 100 then 'TC' else 'TP'||lpad(pct, 2, '0') end,
case when pct = 100 then 'TC' else 'TP'||lpad(pct, 2, '0') end,
case when pct = 100 then 'Temps Complet' else 'Temps Partiel '||pct||'%' end,
case when pct = 100 then 'Temps Complet' else 'Temps Partiel '||pct||'%' end
from w_ttt
WHERE case when pct = 100 then 'TC' else 'TP'||lpad(pct, 2, '0') end NOT IN (SELECT code_original FROM rh.t_types_temps_travail)
group by 1,2,3,4
;
-- Màj des types d'horaire
INSERT INTO rh.t_types_horaire(code_original, code, texte, texte_court)
select '0', 'J', 'Jour', 'Jour'
where '0' NOT IN (SELECT code_original FROM rh.t_types_horaire)
union
select '-1', 'N', 'Nuit', 'Nuit'
where '-1' NOT IN (SELECT code_original FROM rh.t_types_horaire)
;
-- @todo Màj des services
-- INSERT INTO rh.t_services(code_original, code, texte, texte_court)
-- SELECT svc_code, svc_code, max(svc_court), max(svc_court)
-- FROM prod_cegi.PYSERVICE
-- WHERE svc_code NOT IN (SELECT code_original FROM rh.t_services)
-- GROUP BY 1,2
-- ;
-- @todo Màj des spécialités
-- Màj des codes emploi
INSERT INTO rh.t_codes_emploi(code_original, code, texte, texte_court)
SELECT cpt_emploi, substr(md5(libelle), 1, 5), libelle, substr(libelle, 1, 50)
FROM prod_cegialpha.fnp_tab_emp_emplois
WHERE cpt_emploi NOT IN (SELECT code_original FROM rh.t_codes_emploi)
GROUP BY 1,2,3,4
;
-- @todo Màj des grilles
-- INSERT INTO rh.t_grilles(code_original, code, texte, texte_court)
-- SELECT rpad(gri_code, 5, '0')||ech_ordre, rpad(gri_code, 5, '0')||ech_ordre, ech_ordre||' : '||ech_echelon, substr(ech_ordre||' : '||ech_echelon,1,50)
-- FROM prod_cegi.PYECHELON
-- JOIN prod_cegi.PYGRILLEIND ON PYGRILLEIND.gri_id = PYECHELON.gri_id
-- WHERE rpad(gri_code, 5, '0')||ech_ordre NOT IN (SELECT code_original FROM rh.t_grilles)
-- ;
-- @todo Màj des groupes de grilles
-- INSERT INTO rh.t_grilles_groupes(code_original, code, texte, texte_court)
-- SELECT rpad(gri_code, 5, '0'), rpad(gri_code, 5, '0'), gri_libelle, substr(gri_libelle,1,50)
-- FROM prod_cegi.PYGRILLEIND
-- WHERE rpad(gri_code, 5, '0') NOT IN (SELECT code_original FROM rh.t_grilles_groupes)
-- ;
-- Màj des motifs d'arret -- fnp_tab_nat_natures_temps / fnp_dic_ats_motifs_absence
INSERT INTO rh.t_motifs_arret(code_original, code, texte, texte_court)
SELECT cpt_nature_temps, identifiant_nature, libelle, substr(libelle, 1, 50)
FROM prod_cegialpha.fnp_tab_nat_natures_temps
WHERE cpt_nature_temps NOT IN (SELECT code_original FROM rh.t_motifs_arret)
GROUP BY 1,2,3,4
;
-- Màj des "Comptes"
-- INSERT INTO rh.t_compte(oid, code_original, code, texte, texte_court)
-- ;
]]></sqlcmd>
</NODE>
</NODE>
<NODE name="PROD" label="RECUPERATION DES DONNEES DE PRODUCTION">
<NODE label="Paramétrage des rubriques">
<sqlcmd><![CDATA[
-- Heures payées
update rh.t_rubriques set
p_detail = true,
p_base = true,
c_base = 1,
p_heures_payees = true,
s_heures_payees = 1,
p_heures_travaillees = true,
s_heures_travaillees = 1
where 1=1
and (1!=1
or code = '0001'
or code between '0500' and '0699')
and not user_modified
;
-- Brut
update rh.t_rubriques set
p_detail = true,
p_base = true,
c_base = 1,
p_brut = true,
s_brut = 3,
p_masse_salariale = true,
s_masse_salariale = 3,
p_net_imposable =true,
s_net_imposable = 3,
p_net_a_payer = true,
s_net_a_payer = 3
where 1=1
and code between '1000' and '4999'
and not user_modified
;
-- Cot sal/pat
update rh.t_rubriques set
p_detail = true,
p_base = true,
c_base = 1,
p_masse_salariale = true,
s_masse_salariale = 5,
p_cotisation_salarie = true,
s_cotisation_salarie = 3,
p_cotisation_patronale = true,
s_cotisation_patronale = 5,
p_net_imposable =true,
s_net_imposable = 3,
p_net_a_payer = true,
s_net_a_payer = 3
where 1=1
and code between '5000' and '7999'
and not user_modified
;
-- Od sal
update rh.t_rubriques set
p_detail = true,
p_base = true,
c_base = 1,
p_od_net_salarie = true,
s_od_net_salarie = 3,
p_net_a_payer = true,
s_net_a_payer = 3
where 1=1
and code between '8000' and '9999'
and not user_modified
;
]]></sqlcmd>
</NODE>
<NODE label="Chiffrier">
<sqlcmd><![CDATA[
DROP TABLE IF EXISTS w_bul
;
CREATE TEMP TABLE w_bul AS
with w_cur_bul as (
select cpte_bulletin
from prod_cegialpha.fnp_ppa_bul_bulletins_d
group by 1)
select -- mois en cours.
cpt_bulletin as cpt_bulletin,
periode_paie_deb::date as date_debut,
periode_paie_fin::date as date_fin,
to_char(periode_paie_fin, 'YYYYMM')::int as mois,
base.cti_first_day(to_date(annee_mois, 'YYYYMM')) as date_debut_paie,
base.cti_last_day(to_date(annee_mois, 'YYYYMM')) as date_fin_paie,
date_paiement::date as date_paie,
annee_mois,
cpte_contrat,
cpte_personne,
code_dossier_gestion,
w_ets.entreprise_id,
w_ets.etablissement_id,
heures_remunerees as heures_payees,
salaire_brut as montant_brut,
salaire_net_imposable as montant_net_imposable_salarie,
salaire_net as montant_net_a_payer_salarie,
retenues_salariales as montant_cotisation_salarie,
retenues_patronales as montant_cotisation_patronale,
divers as montant_od_net_salarie,
cout_employeur as montant_masse_salariale
from prod_cegialpha.fnp_ppa_bul_bulletins
join w_cur_bul on w_cur_bul.cpte_bulletin = fnp_ppa_bul_bulletins.cpt_bulletin -- permet de ne remonter que les bulletins en cours ayant du contenu.
join prod_cegialpha.fnp_tab_ctr_contrats_avenants on fnp_tab_ctr_contrats_avenants.cpt_contrat = fnp_ppa_bul_bulletins.cpte_contrat
JOIN w_ets ON w_ets.code_dossier = fnp_ppa_bul_bulletins.code_dossier_gestion
UNION ALL
select -- clôturés année courante.
cpt_bul_annee as cpt_bulletin,
periode_paie_deb::date as date_debut,
periode_paie_fin::date as date_fin,
to_char(periode_paie_fin, 'YYYYMM')::int as mois,
base.cti_first_day(to_date(annee_mois, 'YYYYMM')) as date_debut_paie,
base.cti_last_day(to_date(annee_mois, 'YYYYMM')) as date_fin_paie,
date_paiement::date as date_paie,
annee_mois,
cpte_contrat,
cpte_personne,
code_dossier_gestion,
w_ets.entreprise_id,
w_ets.etablissement_id,
heures_remunerees,
salaire_brut,
salaire_net_imposable,
salaire_net,
retenues_salariales,
retenues_patronales,
divers,
cout_employeur
from prod_cegialpha.fnp_ppa_bul_annee
JOIN w_ets ON w_ets.code_dossier = fnp_ppa_bul_annee.code_dossier_gestion
UNION ALL
select -- historique des années précèdentes.
cpt_bul_annee_hist as cpt_bulletin,
periode_paie_deb::date as date_debut,
periode_paie_fin::date as date_fin,
to_char(periode_paie_fin, 'YYYYMM')::int as mois,
base.cti_first_day(to_date(annee_mois, 'YYYYMM')) as date_debut_paie,
base.cti_last_day(to_date(annee_mois, 'YYYYMM')) as date_fin_paie,
date_paiement::date as date_paie,
annee_mois,
cpte_contrat,
cpte_personne,
code_dossier_gestion,
w_ets.entreprise_id,
w_ets.etablissement_id,
heures_remunerees,
salaire_brut,
salaire_net_imposable,
salaire_net,
retenues_salariales,
retenues_patronales,
divers,
cout_employeur
from prod_cegialpha.fnp_ppa_bul_annees_hist
JOIN w_ets ON w_ets.code_dossier = fnp_ppa_bul_annees_hist.code_dossier_gestion
WHERE annee_mois >= 201401
;
TRUNCATE rh.p_chiffrier_production
;
INSERT INTO rh.p_chiffrier_production (entreprise_id, etablissement_id, mois, nombre_salaries, montant_brut, nombre_heures)
SELECT
entreprise_id,
etablissement_id,
annee_mois,
count(distinct cpte_personne),
sum(montant_brut),
sum(heures_payees)
from w_bul
GROUP BY 1,2,3
;
]]></sqlcmd>
</NODE>
<NODE label="Profils">
<sqlcmd><![CDATA[
-- Periode de paie en cours
DROP TABLE IF EXISTS w_periode
;
CREATE TEMP TABLE w_periode AS
SELECT
base.cti_first_day((max(annee_mois)::text||'01')::date) as date_paie_deb_encours,
base.cti_last_day((max(annee_mois)::text||'01')::date) as date_paie_fin_encours,
max(annee_mois)::numeric as mois_paie_encours
FROM prod_cegialpha.fnp_ppa_bul_bulletins
;
-- Création d'une table de contrats avec dates traitées.
DROP TABLE IF EXISTS w_cnt
;
CREATE TEMP TABLE w_cnt AS
select
cpt_contrat,
identifiant_contrat,
horaire_contractuel,
cpte_personne,
cpte_emploi,
code_type_contrat,
date_debut_contrat::date as date_debut,
case when date_fin_reelle is null then '2099-12-31'::date else date_fin_reelle end::date as date_fin,
code_dad_motif_debut,
code_dad_motif_fin,
code_dad_statut_prof,
code_dad_statut_cate,
code_dad_statut_cat_ccnt,
lower(substr(code_csp, 1, 4)) as code_csp, -- CSP
fnp_tab_ctr_contrats_avenants.cpte_coc, --
cpte_groupe, --
cpte_qualification,
fnp_tab_ctr_contrats_avenants.horaire_contractuel/fnp_tab_gtp_horaires.horaire_hebdo as etp_cnt,
bl_travail_nuit::text, -- 0 = jour sinon nuit.
cpte_ets_reference,
w_ets.entreprise_id,
w_ets.etablissement_id
from prod_cegialpha.fnp_tab_ctr_contrats_avenants
-- join prod_cegialpha.fnp_tab_per_personnes on fnp_tab_per_personnes.cpt_personne = fnp_tab_ctr_contrats_avenants.cpte_personne
JOIN w_ets ON w_ets.cpte_structure = fnp_tab_ctr_contrats_avenants.cpte_ets_reference
join prod_cegialpha.fnp_tab_emp_emplois on fnp_tab_emp_emplois.cpt_emploi = fnp_tab_ctr_contrats_avenants.cpte_emploi
join prod_cegialpha.fnp_tab_str_horaires on fnp_tab_str_horaires.cpte_structure=fnp_tab_ctr_contrats_avenants.cpte_ets_reference
join prod_cegialpha.fnp_tab_gtp_horaires on 1=1
and fnp_tab_gtp_horaires.cpt_horaire=fnp_tab_str_horaires.cpte_horaire
and fnp_tab_gtp_horaires.cpt_horaire=fnp_tab_ctr_contrats_avenants.cpte_horaire_ref
;
-- Identification des dates limites pour chaque salariés (pour des raisons de performances).
-- Basé sur les contrats et les bulletins (historique des cumuls t_hcum).
DROP TABLE IF EXISTS w_lim_sal
;
CREATE TEMP TABLE w_lim_sal AS
select
cpte_personne,
identifiant_personne as matricule,
min(date_debut) as date_debut,
max(date_fin) as date_fin
from (
select
cpte_personne,
min(date_debut) as date_debut,
coalesce(nullif(max(date_fin), '2099-12-31'::date), max(date_paie_fin_encours)) 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_cnt, w_periode
group by 1
UNION ALL
select
cpte_personne,
min(date_debut_paie) as date_debut,
max(date_fin_paie) as date_fin
from w_bul
group by 1
) as subq
join prod_cegialpha.fnp_tab_per_personnes on fnp_tab_per_personnes.cpt_personne = subq.cpte_personne
group by 1,2
;
DROP TABLE IF EXISTS w_evt_mois
;
CREATE TEMP TABLE w_evt_mois AS
select
w_lim_sal.cpte_personne,
w_lim_sal.matricule,
cpt_contrat, -- contrat
cpt_bulletin, -- bulletins
p_calendrier.mois,
min(p_calendrier.date) as date_debut,
max(p_calendrier.date) as date_fin
from base.p_calendrier
join w_lim_sal on p_calendrier.date between w_lim_sal.date_debut and w_lim_sal.date_fin
left join w_cnt on 1=1
and w_cnt.cpte_personne = w_lim_sal.cpte_personne
and p_calendrier.date between w_cnt.date_debut and w_cnt.date_fin
left join w_bul on 1=1
and w_bul.cpte_personne = w_lim_sal.cpte_personne
and p_calendrier.date between w_bul.date_debut_paie and w_bul.date_fin_paie
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
having 1!=1
or cpt_contrat is not null -- on ne conserve que les évenements ou il y a un contrat OU
or cpt_bulletin is not null -- un bulletin
;
DROP TABLE IF EXISTS w_profils
;
CREATE TEMP TABLE w_profils AS
select
row_number() over () as row_id,
0 as profil_id,
0 as contrat_id,
0 as contrat_mois_id,
0 as salarie_id,
w_evt_mois.cpte_personne,
w_evt_mois.matricule,
w_evt_mois.mois,
w_evt_mois.date_debut,
w_evt_mois.date_fin,
coalesce(w_cnt.entreprise_id, w_bul.entreprise_id, 0) as entreprise_id,
coalesce(w_cnt.etablissement_id, w_bul.etablissement_id, 0) as etablissement_id,
-- **** contrat ****
w_cnt.cpt_contrat,
w_cnt.identifiant_contrat,
w_cnt.etp_cnt,
coalesce(w_cnt.cpt_contrat, -- si la valeur est renseignée sur la ligne courante, on la prend.
(max(case when w_cnt.cpt_contrat is null then null else ARRAY[extract(epoch from w_evt_mois.date_debut)::text, w_cnt.cpt_contrat] end) over wb)[2], -- sinon on prend la valeur renseignée la plus proche dans le passé
(min(case when w_cnt.cpt_contrat is null then null else ARRAY[extract(epoch from w_evt_mois.date_debut)::text, w_cnt.cpt_contrat] end) over wf)[2], -- sinon on prend la valeur renseignée la plus proche dans le futur
null -- sinon on prend null. Ne devrait pas arriver.
) as cti_cnt_all, -- cpt_contrat mais renseigné avec les valeurs précédentes ou suivantes lorsque hors période de contrat. Utile pour p_contrats_mois.
w_cnt.date_debut as cnt_date_debut,
w_cnt.date_fin as cnt_date_fin,
-- **** bulletins ****
w_bul.cpt_bulletin,
--w_bul.date_debut as bul_date_debut,
--w_bul.date_fin as bul_date_fin,
case when w_cnt.cpt_contrat is null then 1 else 0 end as est_hors_periode,
-- **** code original ****
coalesce(code_csp, chr(1)||'*') AS categorie_socio_professionnelle_code_original,
coalesce(cpte_emploi, chr(1)||'*') AS code_emploi_code_original,
chr(1)||'*' AS grille_code_original,
chr(1)||'*' AS grille_groupe_code_original,
coalesce(cpte_groupe, chr(1)||'*') AS groupe_cotisant_code_original,
coalesce(code_dad_motif_debut, chr(1)||'*') as motif_debut_code_original,
coalesce(code_dad_motif_fin, chr(1)||'*') as motif_fin_code_original,
coalesce(cpte_qualification, chr(1)||'*') AS qualification_code_original,
chr(1)||'*' AS section_analytique_code_original,
chr(1)||'*' AS section_analytique_paie_code_original,
chr(1)||'*' AS service_code_original, -- @todo
chr(1)||'*' AS societe_interim_code_original,
chr(1)||'*' AS specialite_code_original, -- @todo
coalesce(code_dad_statut_prof, chr(1)||'*') AS statut_code_original,
coalesce(code_type_contrat, chr(1)||'*') as type_contrat_code_original,
coalesce(bl_travail_nuit, chr(1)||'*') AS type_horaire_code_original,
coalesce(case when etp_cnt = 1 then 'TC' else 'TP'||lpad(round(etp_cnt * 100, 2), 2, '0') end, chr(1)||'*') AS type_temps_travail_code_original, -- @todo
-- Public
chr(1)||'*' AS cadre_emploi_code_original,
chr(1)||'*' AS categorie_conge_code_original,
chr(1)||'*' AS categorie_statutaire_code_original,
chr(1)||'*' AS commission_paritaire_code_original,
chr(1)||'*' AS compte_salarie_code_original,
chr(1)||'*' AS filiere_code_original,
chr(1)||'*' AS lettre_budgetaire_code_original,
chr(1)||'*' AS unite_fonctionnelle_code_original
from w_evt_mois
left join w_cnt on w_cnt.cpt_contrat = w_evt_mois.cpt_contrat
left join w_bul on w_bul.cpt_bulletin = w_evt_mois.cpt_bulletin
window wb as (PARTITION BY w_evt_mois.cpte_personne ORDER BY w_evt_mois.date_debut rows unbounded preceding), -- sélectionne les lignes précédentes
wf as (PARTITION BY w_evt_mois.cpte_personne ORDER BY w_evt_mois.date_debut rows between current row and unbounded following) -- sélectionne les lignes suivantes
;
]]></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
rhp('finess') AS finess,
nom AS nom,
prenom AS prenom,
date_naissance::date AS date_naissance,
CASE WHEN code_sexe = 'Masculin'
THEN 'M'
ELSE 'F'
END AS sexe,
identifiant_personne AS matricule,
identifiant_personne AS code,
fnp_tab_per_personnes.cpt_personne AS code_original,
w_ets.entreprise_id AS entreprise_id,
coalesce(t_nationalites.oid, 0) AS nationalite_id,
coalesce(t_codes_postaux.oid, 0) AS code_postal_id,
nom_jeune_fille AS nom_naissance,
coalesce(t_situations_famille.oid, 0) AS situation_famille_id,
(max(distinct array[w_profils.date_fin::text, profil_id::text]))[2]::bigint AS profil_id,
min(cnt_date_debut) AS date_debut,
max(cnt_date_fin) AS date_fin,
min(cnt_date_debut) AS date_entree_ets,
max(cnt_date_fin) AS date_sortie_ets,
min(cnt_date_debut) AS date_anciennete,
-- 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 prod_cegialpha.fnp_tab_per_personnes
JOIN prod_cegialpha.fnp_tab_ctr_contrats_avenants on fnp_tab_ctr_contrats_avenants.cpte_personne = fnp_tab_per_personnes.cpt_personne
JOIN w_profils ON w_profils.cpte_personne = fnp_tab_per_personnes.cpt_personne
JOIN w_ets ON w_ets.cpte_structure = fnp_tab_ctr_contrats_avenants.cpte_ets_reference
left join prod_cegialpha.fnp_tab_adr_adresses on 1=1
and fnp_tab_adr_adresses.cpte_personne = fnp_tab_per_personnes.cpt_personne
and fnp_tab_adr_adresses.bl_principale = -1 -- la dernière adresse connue.
LEFT JOIN base.t_codes_postaux ON t_codes_postaux.code = fnp_tab_adr_adresses.code_postal
LEFT JOIN rh.t_nationalites ON t_nationalites.code_original = fnp_tab_per_personnes.code_nationalite
LEFT JOIN rh.t_situations_famille ON t_situations_famille.code_original = fnp_tab_per_personnes.code_situation_fam
GROUP BY 1,2,3,4,5,6,7,8,9,10,11,12,13,20,21,22,23,24
;
]]></sqlcmd>
</NODE>
<NODE name="SALARIE" type="common" />
<NODE label="Salariés (màj oid)">
<sqlcmd><![CDATA[
UPDATE w_profils
SET salarie_id = p_salaries.oid
FROM rh.p_salaries
WHERE w_profils.matricule = p_salaries.matricule
;
UPDATE w_profils
SET salarie_id = p_salaries.oid
FROM rh.p_salaries
WHERE w_profils.cpte_personne = p_salaries.code_original AND
salarie_id = 0
;
]]></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 AS salarie_id,
w_profils.cnt_date_debut AS date_debut,
w_profils.cnt_date_fin AS date_fin,
w_profils.identifiant_contrat AS numero_contrat,
w_profils.cpt_contrat AS code_original,
coalesce((max(distinct array[extract(epoch from w_profils.date_fin), w_profils.etablissement_id]))[2], 0)AS etablissement_id,
coalesce((max(distinct array[extract(epoch from w_profils.date_fin), w_profils.profil_id]))[2], 0) as profil_id
FROM w_profils
JOIN rh.p_salaries ON p_salaries.code_original = w_profils.cpte_personne
WHERE w_profils.cpt_contrat is not null
GROUP BY 1,2,3,4,5
;
-- -- #correction
-- -- <strike>Si les dates d'entrée/sortie d'établissement semblent incohérentes par rapports aux dates des contrats, les corriger.</strike>
-- UPDATE rh.p_salaries
-- SET date_entree_ets = date_debut_contrat
-- FROM (SELECT salarie_id, min(date_debut) AS date_debut_contrat from rh.p_contrats group by 1) subview
-- WHERE 1=1
-- AND p_salaries.oid = subview.salarie_id
-- -- AND date_debut_contrat < date_entree_ets -- On corrige désormais TOUTES les dates d'entrées ets. car cela pose des soucis de calcul
-- -- des TOPs entrée/sortie ets. dans p_contrats_mois.
-- ;
-- UPDATE rh.p_salaries
-- SET date_sortie_ets = date_fin_contrat
-- FROM (SELECT salarie_id, max(date_fin) AS date_fin_contrat from rh.p_contrats group by 1) subview
-- WHERE 1=1
-- AND p_salaries.oid = subview.salarie_id
-- AND date_fin_contrat > date_sortie_ets
-- ;
-- 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
;
DROP TABLE IF EXISTS w_contrats_mois
;
CREATE TEMP TABLE w_contrats_mois AS
SELECT
nextval('rh.s_contrats_mois'::regclass) as contrat_mois_id,
p_salaries.oid AS salarie_id,
p_contrats.oid AS contrat_id,
w_profils.mois AS mois_activite,
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 w_profils.cnt_date_debut BETWEEN w_profils.date_debut AND w_profils.date_fin THEN 1 ELSE 0 END AS nombre_debut_contrat,
CASE WHEN w_profils.cnt_date_fin BETWEEN w_profils.date_debut AND w_profils.date_fin THEN 1 ELSE 0 END AS nombre_fin_contrat,
w_profils.est_hors_periode,
CASE WHEN w_profils.date_debut BETWEEN w_profils.cnt_date_debut AND w_profils.cnt_date_fin THEN 1 ELSE 0 END AS present_debut_mois,
CASE WHEN w_profils.date_fin BETWEEN w_profils.cnt_date_debut AND w_profils.cnt_date_fin THEN 1 ELSE 0 END AS present_fin_mois,
case when cpt_contrat IS NOT NULL then w_profils.etp_cnt -- Il n'y a pas d'ETP contrat ni d'anciennetés pour les contrats_mois hors période.
* (
(least(w_profils.date_fin, w_profils.cnt_date_fin) - greatest(w_profils.date_debut, w_profils.cnt_date_debut) + 1)::numeric
/
(base.cti_last_day(to_date(w_profils.mois, 'YYYYMM')) - to_date(w_profils.mois, 'YYYYMM') + 1)::numeric
) else 0 end AS equivalent_temps_plein,
base.cti_age(least(w_profils.date_fin, w_profils.cnt_date_fin), coalesce(p_salaries.date_naissance, '1962-04-18'::date), 'ny') AS age_id,
least(w_profils.date_fin, w_profils.cnt_date_fin)::date - coalesce(p_salaries.date_naissance, '1962-04-18'::date) AS age_jours,
case when cpt_contrat IS NOT NULL then p_contrats.anciennete_anterieure_jours
+ (w_profils.date_fin - w_profils.cnt_date_debut)
+ 1
else 0 end AS anciennete_jours,
case when cpt_contrat IS NOT NULL then base.cti_age(date_trunc('month', w_profils.date_fin::date)::date, date_trunc('month', w_profils.cnt_date_debut)::date, 'nm')
+ greatest(p_contrats.anciennete_anterieure_mois, p_contrats.anciennete_anterieure_calculee_mois) + 1 else 0 end AS anciennete_mois,
case when cpt_contrat IS NOT NULL then floor((base.cti_age(date_trunc('month', w_profils.date_fin::date)::date, date_trunc('month', w_profils.cnt_date_debut)::date, 'nm')
+ greatest(p_contrats.anciennete_anterieure_mois, p_contrats.anciennete_anterieure_calculee_mois) + 1) / 12) else 0 end AS anciennete_annee_id,
coalesce(w_profils.etablissement_id, p_contrats.etablissement_id, 0) as etablissement_id,
array_agg(w_profils.row_id) as array_row_id -- array des profils.
FROM w_profils
JOIN rh.p_salaries ON w_profils.salarie_id = p_salaries.oid
LEFT JOIN rh.p_contrats ON p_contrats.code_original = w_profils.cti_cnt_all
WHERE false -- Il faut au moins un contrat ou un bulletin.
OR cpt_contrat IS NOT NULL
OR cpt_bulletin IS NOT NULL
GROUP BY 2,3,4,5,6,7,8,9,10,11,12,13,14,15,16,17,18,19,20
;
-- On renseigne les id de contrats de w_profils.
UPDATE w_profils SET
contrat_id = subq.contrat_id,
contrat_mois_id = subq.contrat_mois_id
FROM (
select
unnest(array_row_id) as row_id,
contrat_mois_id,
contrat_id
from w_contrats_mois) as subq
WHERE w_profils.row_id = subq.row_id
;
INSERT INTO rh.p_contrats_mois(
oid,
salarie_id,
contrat_id,
mois_activite,
date_debut,
date_fin,
nombre_entrees,
nombre_departs,
nombre_debut_contrat,
nombre_fin_contrat,
est_hors_periode, -- bulletins de paie hors période de contrat.
present_debut_mois,
present_fin_mois,
equivalent_temps_plein,
age_id,
age_jours,
anciennete_jours,
anciennete_mois,
anciennete_annee_id,
etablissement_id)
SELECT
contrat_mois_id,
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,
age_id,
age_jours,
anciennete_jours,
anciennete_mois,
anciennete_annee_id,
etablissement_id
FROM w_contrats_mois
;
SELECT base.cti_stash_pop_table_indexes('rh.p_contrats_mois')
;
/* Présents fin de mois */
DROP TABLE IF EXISTS w_presents_fin_mois
;
CREATE TEMP TABLE w_presents_fin_mois AS
SELECT
p_contrats.salarie_id,
date(p_contrats_mois.date_debut - interval '1 day') AS date_presence
FROM rh.p_contrats_mois
JOIN rh.p_contrats ON p_contrats_mois.contrat_id = p_contrats.oid
WHERE 1=1
AND fictif <> '1'
AND est_hors_periode <> '1'
AND date_part('day',p_contrats_mois.date_debut) = 01
GROUP BY 1,2
;
UPDATE rh.p_contrats_mois
SET present_fin_mois = '1'
FROM w_presents_fin_mois
WHERE p_contrats_mois.salarie_id = w_presents_fin_mois.salarie_id AND
p_contrats_mois.date_fin = w_presents_fin_mois.date_presence AND
present_fin_mois <> '1' AND
fictif <> '1' AND
est_hors_periode <> '1'
;
UPDATE rh.p_contrats_mois
SET present_fin_mois = '0'
WHERE present_fin_mois = '1' AND
(
date_part('day',date_fin+interval '1 day') <> 1 OR
fictif = '1' OR
est_hors_periode = '1'
)
;
UPDATE rh.p_contrats_mois
SET present_fin_mois = '0'
FROM
(
SELECT oid
FROM rh.p_contrats_mois
LEFT JOIN w_presents_fin_mois ON
p_contrats_mois.salarie_id = w_presents_fin_mois.salarie_id AND
p_contrats_mois.date_fin = w_presents_fin_mois.date_presence
WHERE present_fin_mois = '1' AND
w_presents_fin_mois IS NULL
) subview
WHERE p_contrats_mois.oid = subview.oid
;
]]></sqlcmd>
</NODE>
<NODE label="Historique de la paie">
<sqlcmd><![CDATA[
-- Table de correspondance des rubriques.
DROP TABLE IF EXISTS w_rub_corr
;
CREATE TEMP TABLE w_rub_corr AS
SELECT
cpt_rubrique_d,
cpte_rubrique
FROM prod_cegialpha.fnp_ppa_rub_rubriques_d
GROUP BY 1,2
;
DROP TABLE IF EXISTS w_hp0
;
CREATE TEMP TABLE w_hp0 AS
select -- mois en cours.
fnp_ppa_bul_bulletins.cpt_bulletin,
cpte_contrat,
cpte_personne,
code_dossier_gestion,
w_rub_corr.cpte_rubrique,
cpte_organisme,
date_paiement::date as date_paie,
annee_mois as mois_paie,
periode_paie_deb::date as date_debut,
periode_paie_fin::date as date_fin,
to_char(periode_paie_fin, 'YYYYMM')::int as mois,
base::numeric,
taux::numeric,
montant::numeric,
taux_pat::numeric,
montant_pat::numeric
from prod_cegialpha.fnp_ppa_bul_bulletins
join prod_cegialpha.fnp_ppa_bul_bulletins_d on fnp_ppa_bul_bulletins_d.cpte_bulletin = fnp_ppa_bul_bulletins.cpt_bulletin
join prod_cegialpha.fnp_tab_ctr_contrats_avenants on fnp_tab_ctr_contrats_avenants.cpt_contrat = fnp_ppa_bul_bulletins.cpte_contrat
JOIN w_ets ON w_ets.code_dossier = fnp_ppa_bul_bulletins.code_dossier_gestion
JOIN w_rub_corr on w_rub_corr.cpt_rubrique_d = cpte_rubrique_d
UNION ALL
select -- clôturés année courante.
cpt_bul_annee as cpt_bulletin,
cpte_contrat,
cpte_personne,
code_dossier_gestion,
w_rub_corr.cpte_rubrique,
cpte_organisme,
date_paiement::date as date_paie,
annee_mois as mois_paie,
periode_paie_deb::date as date_debut,
periode_paie_fin::date as date_fin,
to_char(periode_paie_fin, 'YYYYMM')::int as mois,
base::numeric,
taux::numeric,
montant::numeric,
taux_pat::numeric,
montant_pat::numeric
from prod_cegialpha.fnp_ppa_bul_annee
join prod_cegialpha.fnp_ppa_bul_annee_d on fnp_ppa_bul_annee_d.cpte_bul_annee = fnp_ppa_bul_annee.cpt_bul_annee
JOIN w_ets ON w_ets.code_dossier = fnp_ppa_bul_annee.code_dossier_gestion
JOIN w_rub_corr on w_rub_corr.cpt_rubrique_d = cpte_rubrique_d
UNION ALL
select -- historique des années précèdentes.
cpt_bul_annee_hist as cpt_bulletin,
cpte_contrat,
cpte_personne,
code_dossier_gestion,
w_rub_corr.cpte_rubrique,
cpte_organisme,
date_paiement::date as date_paie,
annee_mois as mois_paie,
periode_paie_deb::date as date_debut,
periode_paie_fin::date as date_fin,
to_char(periode_paie_fin, 'YYYYMM')::int as mois,
base::numeric,
taux::numeric,
montant::numeric,
taux_pat::numeric,
montant_pat::numeric
from prod_cegialpha.fnp_ppa_bul_annees_hist
join prod_cegialpha.fnp_ppa_bul_annees_hist_d on fnp_ppa_bul_annees_hist_d.cpte_bul_annee_hist = fnp_ppa_bul_annees_hist.cpt_bul_annee_hist
JOIN w_ets ON w_ets.code_dossier = fnp_ppa_bul_annees_hist.code_dossier_gestion
JOIN w_rub_corr on w_rub_corr.cpt_rubrique_d = cpte_rubrique_d
WHERE annee_mois >= 201401
;
CREATE TEMP TABLE w_hp AS
SELECT
cpt_bulletin,
cpte_contrat,
cpte_personne,
code_dossier_gestion,
cpte_rubrique,
cpte_organisme,
date_paie,
mois_paie,
date_debut,
date_fin,
mois,
t_rubriques.oid as rubrique_id,
sum(CASE WHEN p_base THEN (CASE s_base
WHEN 0 THEN base
WHEN 1 THEN base
WHEN 2 THEN taux
WHEN 3 THEN montant
WHEN 4 THEN taux_pat
WHEN 5 THEN montant_pat
WHEN 6 THEN montant + montant_pat
WHEN 7 THEN montant - montant_pat
WHEN 8 THEN -montant + montant_pat
END) ELSE 0 END * c_base) AS base,
sum(CASE WHEN p_nombre THEN (CASE s_nombre
WHEN 0 THEN base
WHEN 1 THEN base
WHEN 2 THEN taux
WHEN 3 THEN montant
WHEN 4 THEN taux_pat
WHEN 5 THEN montant_pat
WHEN 6 THEN montant + montant_pat
WHEN 7 THEN montant - montant_pat
WHEN 8 THEN -montant + montant_pat
END) ELSE 0 END * c_nombre) AS nombre,
sum(CASE WHEN p_heures_payees THEN (CASE s_heures_payees
WHEN 0 THEN base
WHEN 1 THEN base
WHEN 2 THEN taux
WHEN 3 THEN montant
WHEN 4 THEN taux_pat
WHEN 5 THEN montant_pat
WHEN 6 THEN montant + montant_pat
WHEN 7 THEN montant - montant_pat
WHEN 8 THEN -montant + montant_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 taux
WHEN 3 THEN montant
WHEN 4 THEN taux_pat
WHEN 5 THEN montant_pat
WHEN 6 THEN montant + montant_pat
WHEN 7 THEN montant - montant_pat
WHEN 8 THEN -montant + montant_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 taux
WHEN 3 THEN montant
WHEN 4 THEN taux_pat
WHEN 5 THEN montant_pat
WHEN 6 THEN (montant + montant_pat)
WHEN 7 THEN montant - montant_pat
WHEN 8 THEN -montant + montant_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 taux
WHEN 3 THEN montant
WHEN 4 THEN taux_pat
WHEN 5 THEN montant_pat
WHEN 6 THEN montant + montant_pat
WHEN 7 THEN montant - montant_pat
WHEN 8 THEN -montant + montant_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 taux
WHEN 3 THEN montant
WHEN 4 THEN taux_pat
WHEN 5 THEN montant_pat
WHEN 6 THEN montant + montant_pat
WHEN 7 THEN montant - montant_pat
WHEN 8 THEN -montant + montant_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 taux
WHEN 3 THEN montant
WHEN 4 THEN taux_pat
WHEN 5 THEN montant_pat
WHEN 6 THEN montant + montant_pat
WHEN 7 THEN montant - montant_pat
WHEN 8 THEN -montant + montant_pat
END) ELSE 0 END * c_frais_imposables) AS montant_frais_imposables,
sum(taux * 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 taux
WHEN 3 THEN montant
WHEN 4 THEN taux_pat
WHEN 5 THEN montant_pat
WHEN 6 THEN montant + montant_pat
WHEN 7 THEN montant - montant_pat
WHEN 8 THEN -montant + montant_pat
END) ELSE 0 END * c_cotisation_salarie) AS montant_cotisation_salarie,
sum(taux_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 taux
WHEN 3 THEN montant
WHEN 4 THEN taux_pat
WHEN 5 THEN montant_pat
WHEN 6 THEN montant + montant_pat
WHEN 7 THEN montant - montant_pat
WHEN 8 THEN -montant + montant_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 taux
WHEN 3 THEN montant
WHEN 4 THEN taux_pat
WHEN 5 THEN montant_pat
WHEN 6 THEN montant + montant_pat
WHEN 7 THEN montant - montant_pat
WHEN 8 THEN -montant + montant_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 taux
WHEN 3 THEN montant
WHEN 4 THEN taux_pat
WHEN 5 THEN montant_pat
WHEN 6 THEN montant + montant_pat
WHEN 7 THEN montant - montant_pat
WHEN 8 THEN -montant + montant_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 taux
WHEN 3 THEN montant
WHEN 4 THEN taux_pat
WHEN 5 THEN montant_pat
WHEN 6 THEN montant + montant_pat
WHEN 7 THEN montant - montant_pat
WHEN 8 THEN -montant + montant_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 taux
WHEN 3 THEN montant
WHEN 4 THEN taux_pat
WHEN 5 THEN montant_pat
WHEN 6 THEN montant + montant_pat
WHEN 7 THEN montant - montant_pat
WHEN 8 THEN -montant + montant_pat
END) ELSE 0 END * c_net_a_payer) AS montant_net_a_payer_salarie
FROM w_hp0
JOIN rh.t_rubriques on t_rubriques.code_original = w_hp0.cpte_rubrique
WHERE p_detail
GROUP BY 1,2,3,4,5,6,7,8,9,10,11,12
;
DROP TABLE IF EXISTS w_hp_1
;
CREATE TEMP TABLE w_hp_1 AS
SELECT
cpt_bulletin,
cpte_contrat,
cpte_personne,
code_dossier_gestion,
cpte_rubrique,
cpte_organisme,
w_hp.date_paie,
w_hp.mois_paie,
w_hp.date_debut,
w_hp.date_fin,
w_hp.mois,
p_salaries.oid as salarie_id,
p_contrats.oid as contrat_id,
CASE WHEN max(p_contrats_mois.oid) IS NOT NULL
THEN (max(ARRAY[extract(epoch from p_contrats_mois.date_fin), p_contrats_mois.oid]))[2]
ELSE (
SELECT (max(ARRAY[p_contrats_mois.mois_activite, p_contrats_mois.oid]))[2]
FROM rh.p_contrats_mois
WHERE
p_contrats_mois.contrat_id = p_contrats.oid
AND p_contrats_mois.mois_activite < w_hp.mois)
END as contrat_mois_id,
w_hp.rubrique_id,
0 as organisme_cotisation_id, -- @todo
w_hp.base,
w_hp.nombre,
round(w_hp.heures_payees, 2) AS heures_payees, -- arrondis nécessaires pour retomber juste avec les cumuls.
round(w_hp.heures_travaillees, 2) as heures_travaillees,
w_hp.montant_masse_salariale,
w_hp.montant_brut,
w_hp.montant_avantage_nature,
w_hp.montant_frais_imposables,
w_hp.taux_cotisation_salarie,
w_hp.montant_cotisation_salarie,
w_hp.taux_cotisation_patronale,
w_hp.montant_cotisation_patronale,
w_hp.montant_od_net_salarie,
w_hp.montant_od_net_patronale,
w_hp.montant_net_imposable_salarie,
w_hp.montant_net_a_payer_salarie
FROM w_hp
JOIN rh.p_contrats on p_contrats.code_original = w_hp.cpte_contrat
LEFT JOIN rh.p_contrats_mois on 1=1
AND p_contrats_mois.contrat_id = p_contrats.oid
AND p_contrats_mois.mois_activite = mois
JOIN rh.p_salaries on p_salaries.code_original = w_hp.cpte_personne
GROUP BY 1,2,3,4,5,6,7,8,9,10,11,12,13, 15,16,17,18,19,20,21,22,23,24,25,26,27,28,29,30,31,32
;
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,
organisme_cotisation_id,
base,
nombre,
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,
date_debut,
date_fin,
mois_paie,
date_paie,
rubrique_id,
organisme_cotisation_id,
base,
nombre,
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_1
;
-- Calcul de la rubrique C000.
-- Pas la peine de paramétrer une rubrique de cumul dans l'application car
-- il existe une table des bulletins qui reprend les montants cumuls.
-- Peut-être faudra-t-il un jour généré comme pour Sage de fausse rubrique
-- reprenant les montants et devoir les paramétrer.
-- Inserer pour chaque bulletin une ligne 'Ecart cumulé' qui va faire le compte avec le total
WITH somme_detail as (
SELECT
w_hp_1.salarie_id,
w_hp_1.contrat_id,
w_hp_1.contrat_mois_id,
w_hp_1.cpt_bulletin,
w_hp_1.mois_paie,
w_hp_1.date_paie,
w_hp_1.mois,
w_hp_1.date_debut,
w_hp_1.date_fin,
sum(w_hp_1.heures_payees) AS heures_payees,
0 AS heures_travaillees,
sum(w_hp_1.montant_masse_salariale) AS montant_masse_salariale,
sum(w_hp_1.montant_brut) AS montant_brut,
0 AS montant_avantage_nature,
0 AS montant_frais_imposables,
sum(w_hp_1.montant_cotisation_salarie) AS montant_cotisation_salarie,
sum(w_hp_1.montant_cotisation_patronale) AS montant_cotisation_patronale,
-- La somme des OD sal et pat est compensée uniquement dans les OD Sal car la rubrique de cumul Cegi Alpha ne fait pas le distingo.
sum(w_hp_1.montant_od_net_salarie + w_hp_1.montant_od_net_patronale) AS montant_od_net_salarie,
0 AS montant_od_net_patronale,
sum(w_hp_1.montant_net_imposable_salarie) AS montant_net_imposable_salarie,
sum(w_hp_1.montant_net_a_payer_salarie) AS montant_net_a_payer_salarie
FROM w_hp_1
GROUP BY 1,2,3,4,5,6,7,8,9),
diff as (
SELECT
somme_detail.salarie_id,
somme_detail.contrat_id,
somme_detail.contrat_mois_id,
somme_detail.cpt_bulletin,
somme_detail.mois_paie,
somme_detail.date_paie,
somme_detail.mois,
somme_detail.date_debut,
somme_detail.date_fin,
sum(w_bul.heures_payees - somme_detail.heures_payees) AS heures_payees,
--sum(w_bul.heures_travaillees - somme_detail.heures_travaillees) AS heures_travaillees,
0 AS heures_travaillees,
sum(w_bul.montant_masse_salariale - somme_detail.montant_masse_salariale) AS montant_masse_salariale,
sum(w_bul.montant_brut - somme_detail.montant_brut) AS montant_brut,
-- sum(w_bul.montant_avantage_nature - somme_detail.montant_avantage_nature) AS montant_avantage_nature,
0 AS montant_avantage_nature,
--sum(w_bul.montant_frais_imposables - somme_detail.montant_frais_imposables) AS montant_frais_imposables,
0 AS montant_frais_imposables,
sum(w_bul.montant_cotisation_salarie - somme_detail.montant_cotisation_salarie) AS montant_cotisation_salarie,
sum(w_bul.montant_cotisation_patronale - somme_detail.montant_cotisation_patronale) AS montant_cotisation_patronale,
sum(w_bul.montant_od_net_salarie - somme_detail.montant_od_net_salarie) AS montant_od_net_salarie,
-- sum(w_bul.montant_od_net_patronale - somme_detail.montant_od_net_patronale) AS montant_od_net_patronale,
0 AS montant_od_net_patronale,
sum(w_bul.montant_net_imposable_salarie - somme_detail.montant_net_imposable_salarie) AS montant_net_imposable_salarie,
sum(w_bul.montant_net_a_payer_salarie - somme_detail.montant_net_a_payer_salarie) AS montant_net_a_payer_salarie
FROM somme_detail
JOIN w_bul ON w_bul.cpt_bulletin = somme_detail.cpt_bulletin
GROUP BY 1,2,3,4,5,6,7,8,9)
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,
organisme_cotisation_id,
base,
nombre,
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
diff.salarie_id,
diff.contrat_id,
diff.contrat_mois_id,
diff.mois,
diff.date_debut,
diff.date_fin,
diff.mois_paie,
diff.date_paie,
(select oid from rh.t_rubriques where code_original = 'C000'),
0 as organisme_cotisation_id,
0 as base,
0 as nombre,
diff.heures_payees,
diff.heures_travaillees,
diff.montant_masse_salariale,
diff.montant_brut,
diff.montant_avantage_nature,
diff.montant_frais_imposables,
0 as taux_cotisation_salarie,
diff.montant_cotisation_salarie,
0 as taux_cotisation_patronale,
diff.montant_cotisation_patronale,
diff.montant_od_net_salarie,
diff.montant_od_net_patronale,
diff.montant_net_imposable_salarie,
diff.montant_net_a_payer_salarie
FROM diff
WHERE 1!=1
OR diff.heures_payees != 0
OR diff.heures_travaillees != 0
OR diff.montant_brut != 0
OR diff.montant_avantage_nature != 0
OR diff.montant_frais_imposables != 0
OR diff.montant_cotisation_salarie != 0
OR diff.montant_cotisation_patronale != 0
OR diff.montant_od_net_salarie != 0
OR diff.montant_od_net_patronale != 0
OR diff.montant_net_imposable_salarie != 0
OR diff.montant_net_a_payer_salarie != 0
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
;
]]></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
w_profils.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 w_profils ON w_profils.contrat_mois_id = p_contrats_mois.oid
GROUP BY 1,2,3,4,5
;
]]></sqlcmd>
</NODE>
<NODE label="Arrêts de travail">
<sqlcmd><![CDATA[
-- Les absences au sens large sont remontées depuis Cegi.
-- DROP TABLE IF EXISTS w_at
-- ;
-- CREATE TEMP TABLE w_at AS
-- select
-- per_id,
-- abspar_id,
-- abs_id,
-- row_number() OVER (ORDER BY per_id, abs_deb) as row_num,
-- row_number() OVER (ORDER BY per_id, abs_deb desc) as row_num_desc,
-- abs_deb::date,
-- abs_fin::date,
-- (abs_fin+ '1 day'::interval)::date as reprise
-- FROM prod_cegi.pyabsence
-- WHERE abs_deb::date <= current_date
-- ;
-- Aggrégation des arrêts consécutifs ayant un même motif.
-- WITH RECURSIVE rec(row_num, per_id, abs_id, abspar_id, abs_deb, abs_fin) AS (
-- select row_num, per_id, abs_id, abspar_id, abs_deb, abs_fin
-- from w_at
-- where row_num = 1
-- union all
-- select
-- w_at.row_num,
-- w_at.per_id,
-- case when true -- Lorsque...
-- and w_at.per_id = rec.per_id --... même matricule,
-- and w_at.abspar_id = rec.abspar_id -- même motif d'arrêt et
-- and w_at.abs_deb = (rec.abs_fin + '1 day'::interval)::date -- arrêts consécutif
-- then rec.abs_id -- ... alors aggrégation des 2 arrêts,
-- else w_at.abs_id end, -- sinon on laisse tel quel.
-- w_at.abspar_id,
-- w_at.abs_deb,
-- w_at.abs_fin
-- from w_at
-- join rec on w_at.row_num = rec.row_num + 1)
-- UPDATE w_at SET
-- abs_id = rec.abs_id
-- FROM rec
-- WHERE w_at.row_num = rec.row_num
-- ;
-- Mise à jour des dates de reprise.
-- WITH RECURSIVE rec(row_num_desc, per_id, abs_deb, abs_fin, reprise) AS (
-- select row_num_desc, per_id, abs_deb, abs_fin, reprise
-- from w_at
-- where row_num_desc = 1
-- union all
-- select
-- w_at.row_num_desc,
-- w_at.per_id,
-- w_at.abs_deb,
-- w_at.abs_fin,
-- case when true
-- and w_at.per_id = rec.per_id
-- and w_at.reprise between rec.abs_deb and rec.abs_fin
-- then rec.reprise
-- else w_at.reprise end
-- from w_at
-- join rec on w_at.row_num_desc = rec.row_num_desc + 1)
-- UPDATE w_at SET
-- reprise = rec.reprise
-- FROM rec
-- WHERE w_at.row_num_desc = rec.row_num_desc
-- ;
-- TRUNCATE rh.p_arrets_travail
-- ;
-- TRUNCATE rh.p_arrets_travail_mois
-- ;
-- ALTER SEQUENCE rh.s_arrets_travail RESTART WITH 1
-- ;
-- INSERT INTO rh.p_arrets_travail(
-- salarie_id,
-- contrat_id,
-- mois_activite,
-- date_debut,
-- date_fin,
-- date_reprise,
-- motif_arret_id,
-- precision_motif_arret_id,
-- nb_jours
-- )
-- SELECT
-- p_salaries.oid,
-- max(p_contrats.oid),
-- to_char(max(w_at.abs_fin), 'YYYYMM')::numeric,
-- min(w_at.abs_deb),
-- max(w_at.abs_fin),
-- max(w_at.reprise),
-- t_motifs_arret.oid,
-- 0,
-- max(w_at.abs_fin) - min(w_at.abs_deb) + 1
-- FROM w_at
-- JOIN prod_cegi.pydetabsence on pydetabsence.abs_id = w_at.abs_id -- peut y avoir plusieurs lignes pour une même absence. On la garde car elle contient cnt_id.
-- JOIN prod_cegi.pysalarie on pysalarie.per_id = w_at.per_id
-- JOIN prod_cegi.pycontrat on 1=1
-- AND pycontrat.per_id = pydetabsence.per_id
-- AND pycontrat.cnt_id = pydetabsence.cnt_id
-- JOIN prod_cegi.pyabsenceparam on pyabsenceparam.abspar_id = w_at.abspar_id
-- JOIN prod_cegi.ABSENCEPARAM on ABSENCEPARAM.abspar_id=pyabsenceparam.abspar_id
-- JOIN rh.p_salaries on p_salaries.matricule = pysalarie.sal_matricule
-- JOIN rh.p_contrats on p_contrats.code_original = lpad(pysalarie.sal_matricule,10,'0')||lpad(pycontrat.cnt_id,5,'0')
-- JOIN rh.t_motifs_arret on t_motifs_arret.code_original = ABSENCEPARAM.abspar_code
-- --WHERE date_part('year', detabs_fin) >= 2008
-- GROUP BY w_at.abs_id,1,7,8
-- ;
-- INSERT INTO rh.p_arrets_travail_mois(
-- arret_travail_id,
-- salarie_id,
-- contrat_id,
-- contrat_mois_id,
-- mois_activite,
-- nb_debut_arret,
-- nb_fin_arret,
-- nb_reprise_apres_arret,
-- date_debut,
-- date_fin,
-- nb_jours,
-- nb_arret
-- )
-- SELECT
-- arr.oid AS arret_travail_id,
-- arr.salarie_id AS salarie_id,
-- arr.contrat_id AS contrat_id,
-- p_contrats_mois.oid AS contrat_mois_id,
-- cal.mois,
-- CASE WHEN arr.date_debut BETWEEN cal.date_debut AND cal.date_fin THEN 1 ELSE 0 END AS nombre_debut_arret,
-- CASE WHEN arr.date_fin BETWEEN cal.date_debut AND cal.date_fin THEN 1 ELSE 0 END AS nombre_fin_arret,
-- CASE WHEN arr.date_reprise BETWEEN cal.date_debut AND cal.date_fin THEN 1 ELSE 0 END AS nombre_reprise_apres_arret,
-- -- Lorsque la date de reprise est isolée sur un mois (l'arrêt de travail s'est terminé le mois précédent) :
-- -- la date de début = date de reprise,
-- CASE WHEN arr.date_reprise BETWEEN cal.date_debut AND cal.date_fin AND arr.date_fin<cal.date_debut THEN arr.date_reprise ELSE GREATEST(cal.date_debut, arr.date_debut) END AS date_debut,
-- -- la date de fin = date de reprise et
-- CASE WHEN arr.date_reprise BETWEEN cal.date_debut AND cal.date_fin AND arr.date_fin<cal.date_debut THEN arr.date_reprise ELSE LEAST(cal.date_fin, arr.date_fin) END AS date_fin,
-- -- le nb de jours est toujours = 0.
-- CASE WHEN arr.date_reprise BETWEEN cal.date_debut AND cal.date_fin AND arr.date_fin<cal.date_debut THEN 0 ELSE LEAST(cal.date_fin, arr.date_fin)::date - GREATEST(cal.date_debut, arr.date_debut)::date + 1 END AS nb_jours,
-- 1
-- FROM base.p_calendrier_mois AS cal
-- JOIN rh.p_arrets_travail AS arr ON base.cti_overlaps(arr.date_debut, case when arr.date_reprise = (arr.date_fin + '1 day'::interval)::date then arr.date_reprise else arr.date_fin end, cal.date_debut, cal.date_fin)
-- JOIN rh.p_contrats_mois ON 1=1 -- Pas LEFT JOIN car les rares cas où l'arrêt serait hors contrat correspond en fait à une date de reprise (créée par iCTI) sur le 1er jour du mois suivant et où la personne a quitté l'établissement.
-- -- La ventilation mensuelle de reprise n'aurait pas du être générée par CTI car il n'y a pas eu de reprise en fait.
-- AND p_contrats_mois.mois_activite = cal.mois
-- AND p_contrats_mois.contrat_id = arr.contrat_id
-- WHERE cal.date_debut <= current_date
-- ;
]]></sqlcmd>
</NODE>
</NODE>
<NODE name="POST" label="POST-TRAITEMENTS">
<NODE name="DIVERS" type="common"/>
<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>