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.
 
 
 

1669 lines
74 KiB

<?xml version="1.0" encoding="ISO-8859-1"?>
<ROOT>
<NODE name="INIT" label="INITIALISATIONS">
<NODE label="Pre-traitements des tables prestataire">
<sqlcmd><![CDATA[
-- TRAITEMENT de la table prod_cegid.contrattravail
DROP TABLE IF EXISTS w_insee_pays
;
CREATE TEMP TABLE w_insee_pays AS
SELECT
nationalite,
max(code_insee_pays) AS code_insee_pays
FROM prod_qsp.insee_pays
GROUP BY 1
;
]]></sqlcmd>
</NODE>
<NODE name="INIT" type="common" />
<NODE label="Mise à jour des informations permanentes">
<sqlcmd><![CDATA[
-- Màj des Entreprises
INSERT INTO rh.t_entreprises(code, texte, texte_court, code_original)
SELECT seq_etab, rais_soc, substr(rais_soc,1,50), seq_etab
FROM prod_qsp.etab
WHERE seq_etab NOT IN (SELECT code_original FROM rh.t_entreprises)
GROUP BY 1,2,3,4
;
-- Màj des Etablissements
INSERT INTO rh.t_etablissements(code, texte, texte_court, code_original, entreprise_id)
SELECT seq_etab, rais_soc, substr(rais_soc,1,50), seq_etab, t_entreprises.oid
FROM prod_qsp.etab
JOIN rh.t_entreprises ON t_entreprises.code_original = seq_etab
WHERE seq_etab NOT IN (SELECT code_original FROM rh.t_etablissements)
GROUP BY 1,2,3,4,5
;
-- Màj des catégories socio-professionnelles (basé sur une table de faits)
INSERT INTO rh.t_categories_socio_professionnelle(code, code_original, texte, texte_court)
SELECT code_insee_emp, code_insee_emp, lib_insee_emp, substr(lib_insee_emp,1,50)
FROM prod_qsp.insee_emp
WHERE code_insee_emp NOT IN (SELECT code_original FROM rh.t_categories_socio_professionnelle)
GROUP BY 1,2,3,4
;
-- @TODO: Màj des groupes cotisants
-- Màj des motifs de début de contrat
INSERT INTO rh.t_motifs_debut_contrat(code, code_original, texte, texte_court)
SELECT seq_motif_deb, seq_motif_deb, lib_motif, substr(lib_motif,1,50)
FROM prod_qsp.motif_deb
WHERE seq_motif_deb 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, code_original, texte, texte_court)
SELECT seq_motif_fin, seq_motif_fin, lib_motif, substr(lib_motif,1,50)
FROM prod_qsp.motif_fin
WHERE seq_motif_fin NOT IN (SELECT code_original FROM rh.t_motifs_fin_contrat)
GROUP BY 1,2,3,4
;
-- Màj des nationalités
INSERT INTO rh.t_nationalites(code, texte, texte_court, code_original)
SELECT insee_pays.code_insee_pays, salaries.nationalite, substr(salaries.nationalite,1,50), insee_pays.code_insee_pays
FROM prod_qsp.salaries
join w_insee_pays AS insee_pays on insee_pays.nationalite = salaries.nationalite
WHERE insee_pays.code_insee_pays 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, texte, texte_court, code_original)
SELECT seq_caisse, nom_caisse, substr(nom_caisse,1,50), seq_caisse
FROM prod_qsp.caisses_cot
WHERE seq_caisse 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, texte, texte_court, code_original)
SELECT substr(md5(qualif), 1, 8), qualif, qualif, substr(md5(qualif), 1, 8)
FROM prod_qsp.histo_emp
WHERE 1=1
AND length(trim(qualif)) > 0
AND substr(md5(qualif), 1, 8) NOT IN (SELECT code_original FROM rh.t_qualifications)
GROUP BY 1,2,3,4
;
-- Màj des rubriques
INSERT INTO rh.t_rubriques(code, texte, texte_court, code_original, rang_edition)
SELECT
code_rub,
lib_rub,
substr(lib_rub, 1, 50),
seq_rub,
rank() OVER (ORDER BY code_rub)
FROM prod_qsp.rubriques
WHERE 1=1
AND seq_rub NOT IN (SELECT code_original FROM rh.t_rubriques)
GROUP BY 1,2,3,4
;
-- création des rubriques CTI de cumul
INSERT INTO rh.t_rubriques(code, texte, texte_court, code_original, rang_edition)
SELECT 'C000', 'Ecart cumulé', 'Ecart cumulé', 'C000', -1
WHERE 'C000' NOT IN (SELECT code_original FROM rh.t_rubriques)
;
-- Màj des situations de famille
INSERT INTO rh.t_situations_famille(code, texte, texte_court, code_original)
SELECT situation_fam, situation_fam, substr(situation_fam,1,50), situation_fam
FROM prod_qsp.salaries
WHERE 1=1
AND situation_fam 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, texte, texte_court, code_original)
SELECT type_contr, lib_contr, substr(lib_contr,1,50), type_contr
FROM prod_qsp.types_contr
WHERE 1=1
AND type_contr NOT IN (SELECT code_original FROM rh.t_types_contrat)
GROUP BY 1,2,3,4
;
-- Màj des statuts
INSERT INTO rh.t_statuts(code_original, code, texte, texte_court)
SELECT
histo_emp.seq_statut||lpad(code_statut_conv, 2, ' '),
histo_emp.seq_statut||lpad(code_statut_conv, 2, ' '),
lib_statut||' '||code_statut_conv,
substr(lib_statut||' '||code_statut_conv, 1, 50)
FROM prod_qsp.histo_emp
LEFT JOIN prod_qsp.statuts ON statuts.seq_statut = histo_emp.seq_statut
WHERE 1=1
AND histo_emp.seq_statut||lpad(code_statut_conv, 2, ' ') 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 heures_contr IN (151.67, 169, 0) THEN 'TC' ELSE 'TP'||trim(to_char(heures_contr, '000.00')) END,
CASE WHEN heures_contr IN (151.67, 169, 0) THEN 'TC' ELSE 'TP'||trim(to_char(heures_contr, '000.00')) END,
CASE WHEN heures_contr IN (151.67, 169, 0) THEN 'Temps complet' ELSE 'Temps partiel '||replace(round(heures_contr / 151.67 * 100, 2), '.', ',')||' %' END,
CASE WHEN heures_contr IN (151.67, 169, 0) THEN 'Temps complet' ELSE 'Temps partiel '||replace(round(heures_contr / 151.67 * 100, 2), '.', ',')||' %' END
FROM prod_qsp.histo_emp
WHERE 1=1
AND CASE WHEN heures_contr IN (151.67, 169, 0) THEN 'TC' ELSE 'TP'||trim(to_char(heures_contr, '000.00')) END NOT IN (SELECT code_original FROM rh.t_types_temps_travail)
GROUP BY 1,2,3,4
;
-- @TODO Màj des types d'horaire
-- Màj des services
INSERT INTO rh.t_services(code_original, code, texte, texte_court)
SELECT seq_service, code_service, nom_service, substr(nom_service, 1, 50)
FROM prod_qsp.services
WHERE 1=1
AND seq_service NOT IN (SELECT code_original FROM rh.t_services)
GROUP BY 1,2,3,4
;
-- Màj des spécialités
INSERT INTO rh.t_specialites(code_original, code, texte, texte_court)
SELECT seq_nature, code_nature, lib_nature, substr(lib_nature, 1, 50)
FROM prod_qsp.natures_emp
WHERE 1=1
AND seq_nature NOT IN (SELECT code_original FROM rh.t_specialites)
GROUP BY 1,2,3,4
;
-- Màj des codes emploi
INSERT INTO rh.t_codes_emploi(code_original, code, texte, texte_court)
SELECT seq_categorie, seq_categorie, lib_categorie, substr(lib_categorie, 1, 50)
FROM prod_qsp.categories
WHERE 1=1
AND seq_categorie NOT IN (SELECT code_original FROM rh.t_codes_emploi)
GROUP BY 1,2,3,4
;
-- @TODO Màj des sociétés d'interim
-- Màj des grilles
INSERT INTO rh.t_grilles(code_original, code, texte, texte_court)
SELECT
lpad(num_echelon, 4, '0') || lpad(chevron, 2, '0') || lpad(val_coef, 4, '0'),
lpad(num_echelon, 4, '0') || lpad(chevron, 2, '0') || lpad(val_coef, 4, '0'),
'Echelon : '||num_echelon||' - Niveau : '||chevron||' - Coefficient : '||val_coef,
'Ech '||num_echelon||' Niv '||chevron||' Coef '||val_coef
FROM prod_qsp.val_echelon
WHERE 1=1
AND lpad(num_echelon, 4, '0') || lpad(chevron, 2, '0') || lpad(val_coef, 4, '0') NOT IN (SELECT code_original FROM rh.t_grilles)
GROUP BY 1,2,3,4
;
-- Màj des groupes de grilles
INSERT INTO rh.t_grilles_groupes(code_original, code, texte, texte_court)
SELECT code_groupe, code_groupe, code_groupe, substr(code_groupe, 1, 50)
FROM prod_qsp.groupes
WHERE 1=1
AND code_groupe NOT IN (SELECT code_original FROM rh.t_grilles_groupes)
GROUP BY 1
;
-- Màj des comptes
INSERT INTO rh.t_compte(code_original, code, texte, texte_court)
SELECT rad_cpt_compta_sal, rad_cpt_compta_sal, rad_cpt_compta_sal, rad_cpt_compta_sal
FROM prod_qsp.rubriques
WHERE 1=1
AND rad_cpt_compta_sal NOT IN (SELECT code_original FROM rh.t_compte)
GROUP BY 1
UNION
SELECT rad_cpt_compta_pat, rad_cpt_compta_pat, rad_cpt_compta_pat, rad_cpt_compta_pat
FROM prod_qsp.rubriques
WHERE 1=1
AND rad_cpt_compta_pat NOT IN (SELECT code_original FROM rh.t_compte)
GROUP BY 1
;
-- Màj des motifs d'arret
INSERT INTO rh.t_motifs_arret(code_original, code, texte, texte_court)
SELECT
seq_nat_abs,
lib_c_abs,
nature_abs,
substr(nature_abs, 1, 50)
FROM prod_qsp.natures_absence
WHERE 1=1
AND seq_nat_abs NOT IN (SELECT code_original FROM rh.t_motifs_arret)
GROUP BY 1,2,3,4
;
-- @TODO Màj des précisions du motif d'arrêt
-- @TODO Màj des motifs de visite médicale
-- @TODO Màj des circonstances d'accident du travail
-- @TODO Màj des lieux d'accident du travail
-- @TODO Màj de la nature de l'accident du travail
-- @TODO Màj des sièges d'accident du travail
-- @TODO Màj des listes de formations
-- Màj des sections analytiques compta : prévu mais pas alimenté.
-- Màj des sections analytiques paie : prévu mais pas alimenté.
DROP TABLE IF EXISTS temp.x_ref_rubrique
;
CREATE TABLE temp.x_ref_rubrique AS
with rub_det_0 as (
select
histo_lignes_bul.code_rub as code,
histo_lignes_bul.seq_rub as code_original,
histo_lignes_bul.code_rub between '100' and '499' as brut,
false as hresp,
false as hresw,
false as odns,
false as odnp,
histo_lignes_bul.code_rub between '501' and '900' as cosd,
histo_lignes_bul.code_rub between '501' and '900' as copa,
max(lib_rub) as texte
from prod_qsp.histo_lignes_bul
where 1=1
-- and histo_lignes_bul.code_rub not in ('100', '387', '627 A', '627 Z', '699', '700', '896', '899', '900')
-- and histo_lignes_bul.code_rub not in ('898', '147') -- Spécifique Arago (= icti_344).
group by 1,2,3,4,5,6,7,8,9
)
, rub_det_1 as (
select
code,
code_original,
texte,
bool_or(brut) or bool_or(odns) or bool_or(odnp) or bool_or(cosd) or bool_or(copa) AS p_detail,
false AS p_nombre,
bool_or(brut) or bool_or(odns) or bool_or(odnp) or bool_or(cosd) or bool_or(copa) AS p_base,
bool_or(hresp) AS p_heures_payees,
bool_or(hresw) AS p_heures_travaillees,
bool_or(brut) or bool_or(odnp) or bool_or(copa) AS p_masse_salariale,
bool_or(brut) AS p_brut,
false AS p_avantage_nature,
false AS p_frais_imposables,
bool_or(cosd) AS p_cotisation_salarie,
bool_or(copa) AS p_cotisation_patronale,
bool_or(odns) AS p_od_net_salarie,
false AS p_od_net_patronale,
bool_or(brut) or bool_or(cosd) AS p_net_imposable,
-- case when bool_or(cosd) then 1 else -1 end as c_net_imposable,
bool_or(brut) or bool_or(cosd) or bool_or(odns) AS p_net_a_payer
-- case when bool_or(cosd) then 1 else -1 end as c_net_a_payer
from rub_det_0
group by 1,2,3
)
SELECT
code_original,
code,
texte,
null::text as texte_court,
-1 as rang_edition,
false as p_cumul,
p_detail as p_detail,
p_nombre as p_nombre,
0 as s_nombre,
1 as c_nombre,
p_base as p_base,
1 as s_base,
1 as c_base,
false as p_heures_contrat,
0 as s_heures_contrat,
1 as c_heures_contrat,
p_heures_payees as p_heures_payees,
0 as s_heures_payees,
1 as c_heures_payees,
p_heures_travaillees as p_heures_travaillees,
0 as s_heures_travaillees,
1 as c_heures_travaillees,
p_masse_salariale as p_masse_salariale,
case when p_cotisation_patronale or p_od_net_patronale then 5 else 3 end as s_masse_salariale,
case when p_cotisation_patronale then -1 else 1 end as c_masse_salariale,
p_brut as p_brut,
3 as s_brut,
1 as c_brut,
p_avantage_nature as p_avantage_nature,
3 as s_avantage_nature,
1 as c_avantage_nature,
p_frais_imposables as p_frais_imposables,
3 as s_frais_imposables,
1 as c_frais_imposables,
p_cotisation_salarie as p_cotisation_salarie,
3 as s_cotisation_salarie,
1 as c_cotisation_salarie,
p_cotisation_patronale as p_cotisation_patronale,
5 as s_cotisation_patronale,
-1 as c_cotisation_patronale,
p_od_net_salarie as p_od_net_salarie,
3 as s_od_net_salarie,
1 as c_od_net_salarie,
p_od_net_patronale as p_od_net_patronale,
5 as s_od_net_patronale,
1 as c_od_net_patronale,
p_net_imposable as p_net_imposable,
3 as s_net_imposable,
1 as c_net_imposable,
p_net_a_payer as p_net_a_payer,
3 as s_net_a_payer,
1 as c_net_a_payer
FROM rub_det_1
;
-- Pré-paramétrage automatique des rubriques (au mieux).
-- Cette requête n'intervient pas sur les rubriques paramétrées à la main.
update rh.t_rubriques
set
p_cumul = x_ref_rubrique.p_cumul,
p_detail = x_ref_rubrique.p_detail,
p_nombre = x_ref_rubrique.p_nombre,
s_nombre = x_ref_rubrique.s_nombre,
c_nombre = x_ref_rubrique.c_nombre,
p_base = x_ref_rubrique.p_base,
s_base = x_ref_rubrique.s_base,
c_base = x_ref_rubrique.c_base,
p_heures_contrat = x_ref_rubrique.p_heures_contrat,
s_heures_contrat = x_ref_rubrique.s_heures_contrat,
c_heures_contrat = x_ref_rubrique.c_heures_contrat,
p_heures_payees = x_ref_rubrique.p_heures_payees,
s_heures_payees = x_ref_rubrique.s_heures_payees,
c_heures_payees = x_ref_rubrique.c_heures_payees,
p_heures_travaillees = x_ref_rubrique.p_heures_travaillees,
s_heures_travaillees = x_ref_rubrique.s_heures_travaillees,
c_heures_travaillees = x_ref_rubrique.c_heures_travaillees,
p_masse_salariale = x_ref_rubrique.p_masse_salariale,
s_masse_salariale = x_ref_rubrique.s_masse_salariale,
c_masse_salariale = x_ref_rubrique.c_masse_salariale,
p_brut = x_ref_rubrique.p_brut,
s_brut = x_ref_rubrique.s_brut,
c_brut = x_ref_rubrique.c_brut,
p_avantage_nature = x_ref_rubrique.p_avantage_nature,
s_avantage_nature = x_ref_rubrique.s_avantage_nature,
c_avantage_nature = x_ref_rubrique.c_avantage_nature,
p_frais_imposables = x_ref_rubrique.p_frais_imposables,
s_frais_imposables = x_ref_rubrique.s_frais_imposables,
c_frais_imposables = x_ref_rubrique.c_frais_imposables,
p_cotisation_salarie = x_ref_rubrique.p_cotisation_salarie,
s_cotisation_salarie = x_ref_rubrique.s_cotisation_salarie,
c_cotisation_salarie = x_ref_rubrique.c_cotisation_salarie,
p_cotisation_patronale = x_ref_rubrique.p_cotisation_patronale,
s_cotisation_patronale = x_ref_rubrique.s_cotisation_patronale,
c_cotisation_patronale = x_ref_rubrique.c_cotisation_patronale,
p_od_net_salarie = x_ref_rubrique.p_od_net_salarie,
s_od_net_salarie = x_ref_rubrique.s_od_net_salarie,
c_od_net_salarie = x_ref_rubrique.c_od_net_salarie,
p_od_net_patronale = x_ref_rubrique.p_od_net_patronale,
s_od_net_patronale = x_ref_rubrique.s_od_net_patronale,
c_od_net_patronale = x_ref_rubrique.c_od_net_patronale,
p_net_imposable = x_ref_rubrique.p_net_imposable,
s_net_imposable = x_ref_rubrique.s_net_imposable,
c_net_imposable = x_ref_rubrique.c_net_imposable,
p_net_a_payer = x_ref_rubrique.p_net_a_payer,
s_net_a_payer = x_ref_rubrique.s_net_a_payer,
c_net_a_payer = x_ref_rubrique.c_net_a_payer
from temp.x_ref_rubrique
where 1=1
AND t_rubriques.code_original = x_ref_rubrique.code_original
AND NOT t_rubriques.user_modified
;
]]></sqlcmd>
</NODE>
</NODE>
<NODE name="PROD" label="RECUPERATION DES DONNEES DE PRODUCTION">
<NODE label="Chiffrier">
<sqlcmd><![CDATA[
-- Table des bulletins de paie
DROP TABLE IF EXISTS w_bulletins
;
CREATE TEMP TABLE w_bulletins AS
SELECT
row_number() OVER (ORDER BY emplois.num_sal, bulletins.num_bul, bulletins.date_deb) AS bul_id,
bulletins.*,
(case when to_char(bulletins.date_deb, 'YYYYMM') = to_char(bulletins.date_paye, 'YYYYMM') then bulletins.date_deb else bulletins.date_paye end)::date as cti_date_debut,
(case when to_char(bulletins.date_deb, 'YYYYMM') = to_char(bulletins.date_paye, 'YYYYMM') then bulletins.date_fin else bulletins.date_paye end)::date as cti_date_fin,
to_char(bulletins.date_paye, 'YYYYMM')::int as mois_paie,
emplois.num_sal,
0::numeric as etp_contrat
FROM prod_qsp.bulletins
join prod_qsp.emplois ON emplois.seq_emploi = bulletins.seq_emploi
WHERE 1=1
and bulletins.num_bul > 0
-- and bulletins.num_bul_annule = 0 -- On prend tous les bulletins, y compris les réguls.
AND bulletins.date_paye >= rhp('rhprovider_start')::date
;
TRUNCATE rh.p_chiffrier_production
;
INSERT INTO rh.p_chiffrier_production (entreprise_id, etablissement_id, mois, nombre_salaries, montant_brut, nombre_heures)
select
t_entreprises.oid,
t_etablissements.oid,
mois_paie,
count(distinct num_sal),
sum(res_sal),
sum(base)
from w_bulletins AS bulletins
join prod_qsp.histo_lignes_bul ON 1=1
AND histo_lignes_bul.seq_emploi = bulletins.seq_emploi
AND case when histo_lignes_bul.NUM_BUL > 0 then histo_lignes_bul.NUM_BUL else @(histo_lignes_bul.NUM_BUL + 99999) end = bulletins.NUM_BUL
JOIN rh.t_etablissements ON t_etablissements.code_original = 1 -- @todo : code établissement en dur
JOIN rh.t_entreprises ON t_entreprises.oid = t_etablissements.entreprise_id
WHERE 1=1
AND mois_paie >= 200901
AND histo_lignes_bul.code_rub in ('500')
GROUP BY 1,2,3
;
]]></sqlcmd>
</NODE>
<NODE label="Pré-traitements">
<sqlcmd><![CDATA[
DROP TABLE IF EXISTS w_sal_list
;
CREATE TEMP TABLE w_sal_list AS
SELECT num_sal AS mat
FROM w_bulletins
GROUP BY 1
;
-- Table des contrats
DROP TABLE IF EXISTS w_emplois
;
CREATE TEMP TABLE w_emplois AS
SELECT
emplois.*,
date_entree::date AS cti_date_debut,
coalesce(date_sortie, '2099-12-31')::date AS cti_date_fin
FROM prod_qsp.emplois
JOIN w_sal_list ON w_sal_list.mat = emplois.num_sal -- Restriction aux salariés ayant au moins eu un bulletin depuis 2009
;
-- Table historique employé
DROP TABLE IF EXISTS w_histo_emp
;
CREATE TEMP TABLE w_histo_emp AS
with pre as (
SELECT
histo_emp.*,
date_deb_applic::date AS cti_date_debut,
CASE WHEN date_fin_applic::date = '4000-01-01'::date THEN '2099-12-31'::date ELSE date_fin_applic::date END AS cti_date_fin,
w_emplois.num_sal,
w_emplois.motif_entree,
w_emplois.motif_sortie,
w_emplois.cti_date_debut AS emploi_date_debut,
w_emplois.cti_date_fin AS emploi_date_fin,
val_echelon.val_coef,
lpad(val_echelon.num_echelon, 4, '0') || lpad(val_echelon.chevron, 2, '0') || lpad(val_echelon.val_coef, 4, '0') AS grille_code_original
FROM prod_qsp.histo_emp
join w_emplois ON w_emplois.seq_emploi = histo_emp.seq_emploi
left join prod_qsp.val_echelon ON 1=1
AND val_echelon.code_groupe = histo_emp.code_groupe
AND val_echelon.num_echelon = histo_emp.num_echelon
AND val_echelon.chevron = histo_emp.chevron)
select
*,
case when rank() OVER w = 1
then '1900-01-01'::date
else cti_date_debut
end as pro_date_debut,
case when rank() OVER wd = 1
then '2099-12-31'::date
else (lead(cti_date_debut) over w - '1 day'::interval)::date
end as pro_date_fin
from pre
window w as (PARTITION BY num_sal ORDER BY cti_date_debut),
wd as (PARTITION BY num_sal ORDER BY cti_date_debut desc)
;
-- Par salarié, identification de la date min/max d'évènement à but de ventilation.
DROP TABLE IF EXISTS w_min_max
;
CREATE TEMP TABLE w_min_max AS
SELECT
num_sal,
min(min_date) AS min_date,
max(max_date) AS max_date
FROM (
SELECT
num_sal,
min(cti_date_debut) AS min_date,
max(least(current_date, cti_date_fin)) AS max_date
FROM w_histo_emp
GROUP BY 1
UNION ALL
SELECT
num_sal,
min(cti_date_debut) AS min_date,
max(least(current_date, cti_date_fin)) AS max_date
FROM w_bulletins
GROUP BY 1) AS subq
GROUP BY 1
;
DROP TABLE IF EXISTS w_salarie_jours
;
CREATE TEMP TABLE w_salarie_jours AS
SELECT
date,
mois,
w_min_max.num_sal,
w_histo_emp.seq_emploi AS histo_emp_seq_emploi,
w_histo_emp.date_deb_applic::date, -- SEQ_EMPLOI + DATE_DEB_APPLIC : Primary key
w_histo_emp.emploi_date_debut,
w_histo_emp.emploi_date_fin,
w_bulletins.seq_emploi AS bulletins_seq_emploi,
w_bulletins.num_bul, -- SEQ_EMPLOI + NUM_BUL : Primary key
coalesce(heures_contr / 151.67, 1.0) as etp_contrat,
-- Champs du profil.
coalesce(w_histo_emp.code_insee_emp, chr(1)||'*') AS categorie_socio_professionnelle_code_original,
coalesce(grille_code_original, chr(1)||'*') AS grille_code_original,
coalesce(w_histo_emp.code_groupe, chr(1)||'*') AS grille_groupe_code_original,
coalesce(CASE WHEN date = emploi_date_debut THEN w_histo_emp.motif_entree::text ELSE NULL END, chr(1)||'*') AS motif_debut_code_original,
coalesce(CASE WHEN date = emploi_date_fin THEN w_histo_emp.motif_sortie::text ELSE NULL END, chr(1)||'*') AS motif_fin_code_original,
coalesce(substr(md5(w_histo_emp.qualif), 1, 8), chr(1)||'*') AS qualification_code_original,
coalesce(w_histo_emp.seq_service::text, chr(1)||'*') AS service_code_original,
coalesce(w_histo_emp.seq_statut||lpad(code_statut_conv, 2, ' '), chr(1)||'*') AS statut_code_original,
coalesce(w_histo_emp.seq_nature::text, chr(1)||'*') AS specialite_code_original,
coalesce(w_histo_emp.seq_categorie::text, chr(1)||'*') AS code_emploi_code_original,
coalesce(w_histo_emp.type_contr::text, chr(1)||'*') AS type_contrat_code_original,
coalesce(CASE WHEN heures_contr IN (151.67, 169, 0) THEN 'TC' ELSE 'TP'||trim(to_char(heures_contr, '000.00')) END, chr(1)||'*') AS type_temps_travail_code_original
FROM base.p_calendrier
JOIN w_min_max ON date BETWEEN min_date AND max_date
LEFT JOIN w_histo_emp ON 1=1
AND w_histo_emp.num_sal = w_min_max.num_sal
AND date BETWEEN w_histo_emp.pro_date_debut AND w_histo_emp.pro_date_fin
LEFT JOIN w_bulletins ON 1=1
AND w_bulletins.ponc = 0
AND w_bulletins.num_sal = w_min_max.num_sal
AND date BETWEEN w_bulletins.cti_date_debut AND w_bulletins.cti_date_fin
WHERE 1!=1
OR w_histo_emp.seq_emploi IS NOT NULL
OR w_bulletins.seq_emploi IS NOT NULL
;
UPDATE w_bulletins SET
etp_contrat = w_salarie_jours.etp_contrat
FROM w_salarie_jours
WHERE w_salarie_jours.bulletins_seq_emploi = w_bulletins.seq_emploi
;
--Table ventilée mensuellement des évenements salariés.
DROP TABLE IF EXISTS w_salarie_mois
;
CREATE TEMP TABLE w_salarie_mois AS
SELECT
mois,
min(date) AS date_debut,
max(date) AS date_fin,
num_sal,
histo_emp_seq_emploi,
date_deb_applic,
emploi_date_debut,
emploi_date_fin,
max(bulletins_seq_emploi) AS bulletins_seq_emploi,
max(num_bul) AS num_bul,
-- Champs dédiés au privé.
categorie_socio_professionnelle_code_original,
code_emploi_code_original,
grille_code_original,
grille_groupe_code_original,
chr(1)||'*' AS groupe_cotisant_code_original,
max(motif_debut_code_original) AS motif_debut_code_original, -- Max est utilisé ici afin de ne pas créer artificiellement une rupture le dernier jour du contrat pour le motif de début.
-- Le motif de début sera ainsi renseigné pour les jours du dernier mois ventilé.
max(motif_fin_code_original) AS motif_fin_code_original, -- idem ligne précédente.
qualification_code_original,
chr(1)||'*' AS section_analytique_code_original, -- Non renseignée
chr(1)||'*' AS section_analytique_paie_code_original, -- Non renseignée
service_code_original,
chr(1)||'*' AS societe_interim_code_original,
specialite_code_original,
statut_code_original,
type_contrat_code_original,
chr(1)||'*' AS type_horaire_code_original,
type_temps_travail_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_salarie_jours
GROUP BY 1,4,5,6,7,8,11,12,13,14,15,18,19,20,21,22,23,24,25,26,27,28,29,30,31,32,33,34,35
;
]]></sqlcmd>
</NODE>
<NODE label="Pre-traitement des Profils">
<sqlcmd><![CDATA[
-- Création d'une table temp de profils (axé sur les contrats)
DROP TABLE IF EXISTS w_profils
;
CREATE TEMP TABLE w_profils AS
SELECT
0 AS profil_id, -- Identifiant CTI du profil CTI
0 AS last_profil, -- Profil le + récent = 1, sinon à 0
-- Cléfs naturelles QSP
mois,
date_debut,
date_fin,
num_sal,
num_sal AS matricule,
histo_emp_seq_emploi,
date_deb_applic,
emploi_date_debut,
emploi_date_fin,
bulletins_seq_emploi,
num_bul,
-- Données du Profil CTI
-- Champs dédiés au privé.
categorie_socio_professionnelle_code_original,
code_emploi_code_original,
grille_code_original,
grille_groupe_code_original,
groupe_cotisant_code_original,
motif_debut_code_original,
motif_fin_code_original,
qualification_code_original,
section_analytique_code_original, -- Non renseignée
section_analytique_paie_code_original, -- Non renseignée
service_code_original,
societe_interim_code_original,
specialite_code_original,
statut_code_original,
type_contrat_code_original,
type_horaire_code_original,
type_temps_travail_code_original,
-- Champs dédiés au public.
unite_fonctionnelle_code_original,
categorie_conge_code_original,
compte_salarie_code_original,
commission_paritaire_code_original,
lettre_budgetaire_code_original,
cadre_emploi_code_original,
filiere_code_original,
categorie_statutaire_code_original
FROM w_salarie_mois
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
;
-- Marquage du profil le plus récent pour chaque salarié
UPDATE w_profils
SET last_profil = 1
FROM
(
SELECT
num_sal,
max(date_debut) AS date_debut,
(max(array[extract(epoch from date_debut), histo_emp_seq_emploi]))[2] AS histo_emp_seq_emploi
FROM w_profils
GROUP BY 1
) AS subq
WHERE 1=1
AND w_profils.num_sal = subq.num_sal
AND w_profils.date_debut = subq.date_debut
AND w_profils.histo_emp_seq_emploi = subq.histo_emp_seq_emploi
;
]]></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_nai::date AS date_naissance,
CASE WHEN sexe = 1 THEN 'F' ELSE 'M' END AS sexe,
salaries.num_sal AS matricule,
salaries.num_sal AS code,
salaries.num_sal AS code_original,
coalesce(t_entreprises.oid,0) AS entreprise_id,
coalesce(t_nationalites.oid,0) AS nationalite_id,
coalesce(t_codes_postaux.oid,0) AS code_postal_id,
nom_jf AS nom_naissance,
coalesce(t_situations_famille.oid,0) AS situation_famille_id,
((max(ARRAY[w_profils.emploi_date_fin::text, w_profils.profil_id::text]))[2])::bigint AS profil_id, -- dernier profil salarié.
max(w_profils.emploi_date_debut) AS date_debut, -- date de début du dernier contrat.
max(w_profils.emploi_date_fin) AS date_fin, -- date de fin du dernier contrat.
coalesce(date_entree_init::date, '2099-12-31'::date) AS date_entree_ets,
max(w_profils.emploi_date_fin) AS date_sortie_ets,
-- Champs dédiés au public.
'2099-12-31'::date AS date_entree_fp,
'2099-12-31'::date AS date_entree_fph,
0 AS no_adeli,
0 AS code_cotisation_id,
0 AS matricule_retraite
FROM prod_qsp.salaries
JOIN w_insee_pays AS insee_pays on insee_pays.nationalite = salaries.nationalite
JOIN w_profils ON w_profils.matricule = salaries.num_sal AND w_profils.last_profil = 1
LEFT JOIN rh.t_codes_postaux ON t_codes_postaux.code = salaries.code_postal
LEFT JOIN rh.t_situations_famille ON t_situations_famille.code_original = salaries.situation_fam
LEFT JOIN rh.t_entreprises ON t_entreprises.code_original = 1 -- @TODO : code établissement en dur
LEFT JOIN rh.t_nationalites ON t_nationalites.code_original = insee_pays.code_insee_pays
GROUP BY 1,2,3,4,5,6,7,8,9,10,11,12,13,17,19,20,21,22,23
;
UPDATE w_salaries
SET date_entree_ets = subq.date_entree_ets
FROM (
SELECT
num_sal,
min(date_debut) AS date_entree_ets
FROM w_profils
GROUP BY 1) AS subq
WHERE 1=1
AND w_salaries.matricule = subq.num_sal
AND w_salaries.date_entree_ets = '2099-12-31'::date
;
]]></sqlcmd>
</NODE>
<NODE name="SALARIE" type="common" />
<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
coalesce(p_salaries.oid,0) AS salarie_id,
w_profils.emploi_date_debut,
w_profils.emploi_date_fin,
w_profils.histo_emp_seq_emploi AS numero_contrat,
w_profils.histo_emp_seq_emploi AS code_original,
coalesce(t_etablissements.oid,0) AS etablissement_id,
coalesce((max(ARRAY[EXTRACT(EPOCH FROM w_profils.date_fin)::bigint, w_profils.profil_id]))[2], 0) AS profil_id
FROM w_profils
JOIN rh.p_salaries ON p_salaries.matricule = num_sal
JOIN rh.t_etablissements ON t_etablissements.code_original = 1 -- @TODO : code établissement en dur
GROUP BY 1,2,3,4,5,6
;
-- #correction
-- Si les dates d'entrée/sortie d'établissement semblent incohérentes par rapports aux dates des contrats, les corriger.
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) AS s
WHERE 1=1
AND p_salaries.oid = s.salarie_id
AND date_entree_ets > date_debut_contrat
;
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) AS s
WHERE 1=1
AND p_salaries.oid = s.salarie_id
AND to_char(date_entree_ets, 'YYYY')::numeric >= 2009
AND date_entree_ets < date_debut_contrat
;
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) AS s
WHERE 1=1
AND p_salaries.oid = s.salarie_id
AND date_fin_contrat > date_sortie_ets
;
-- Calcul ancienneté au début de contrat
UPDATE rh.p_contrats
SET
anciennete_anterieure_jours = subq.anciennete_anterieure_jours,
anciennete_anterieure_calculee_mois = subq.anciennete_anterieure_calculee_mois
FROM (
SELECT
t1.seq_emploi,
sum((t2.cti_date_fin - t2.cti_date_debut) + 1) AS anciennete_anterieure_jours,
sum((t2.cti_date_fin - t2.cti_date_debut) + 1) / 30 AS anciennete_anterieure_calculee_mois
FROM w_emplois AS t1
JOIN w_emplois AS t2 ON 1=1
AND t2.num_sal = t1.num_sal
AND t2.cti_date_debut < t1.cti_date_debut
group by 1
) AS subq
WHERE 1=1
AND p_contrats.numero_contrat = subq.seq_emploi
;
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,
age_id,
age_jours,
anciennete_jours,
anciennete_mois,
anciennete_annee_id
)
SELECT
p_salaries.oid AS salarie_id,
p_contrats.oid AS contrat_id,
w_salarie_mois.mois AS mois,
w_salarie_mois.date_debut AS date_debut,
w_salarie_mois.date_fin AS date_fin,
CASE WHEN p_salaries.date_entree_ets BETWEEN w_salarie_mois.date_debut AND w_salarie_mois.date_fin THEN 1 ELSE 0 END AS nombre_entrees,
CASE WHEN p_salaries.date_sortie_ets BETWEEN w_salarie_mois.date_debut AND w_salarie_mois.date_fin THEN 1 ELSE 0 END AS nombre_departs,
CASE WHEN p_contrats.date_debut BETWEEN w_salarie_mois.date_debut AND w_salarie_mois.date_fin THEN 1 ELSE 0 END AS nombre_debut_contrat,
CASE WHEN p_contrats.date_fin BETWEEN w_salarie_mois.date_debut AND w_salarie_mois.date_fin THEN 1 ELSE 0 END AS nombre_fin_contrat,
0 AS est_hors_periode,
CASE WHEN base.cti_first_day(w_salarie_mois.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_salarie_mois.date_fin) BETWEEN p_contrats.date_debut AND p_contrats.date_fin THEN 1 ELSE 0 END AS present_fin_mois,
0, -- L'ETP théorique est calculé plus loin à l'issue de la "Ventilation des profils".
base.cti_age(LEAST(w_salarie_mois.date_fin, w_salarie_mois.date_fin), COALESCE(p_salaries.date_naissance, '1962-04-18'::date), 'ny') AS age_id,
LEAST(w_salarie_mois.date_fin, w_salarie_mois.date_fin)::date - COALESCE(p_salaries.date_naissance, '1962-04-18'::date) AS age_jours,
p_contrats.anciennete_anterieure_jours
+ (LEAST(w_salarie_mois.date_fin, w_salarie_mois.date_fin) - p_contrats.date_debut)
+ 1
AS anciennete_jours,
base.cti_months_between(p_contrats.date_debut, w_salarie_mois.date_fin)
+ p_contrats.anciennete_anterieure_calculee_mois
AS anciennete_mois,
floor(
(
base.cti_months_between(p_contrats.date_debut, w_salarie_mois.date_fin)
+ p_contrats.anciennete_anterieure_calculee_mois
) / 12
) AS anciennete_annee_id
FROM w_salarie_mois
JOIN rh.p_contrats ON p_contrats.numero_contrat = w_salarie_mois.histo_emp_seq_emploi
JOIN rh.p_salaries ON p_salaries.matricule = w_salarie_mois.num_sal
WHERE 1=1
AND w_salarie_mois.mois < to_char(now() + '1 month'::interval, 'YYYYMM')
GROUP BY 1,2,3,4,5,6,7,8,9,10,11,12,13,14,15,16,17
;
]]></sqlcmd>
</NODE>
<NODE label="Historique de la paie">
<sqlcmd><![CDATA[
DROP TABLE IF EXISTS w_hp_0
;
CREATE TEMP TABLE w_hp_0 AS
select
bul_id,
num_sal AS matricule,
bulletins.cti_date_debut AS date_debut,
bulletins.cti_date_fin As date_fin,
bulletins.mois_paie,
t_rubriques.oid AS rubrique_id,
histo_lignes_bul.code_rub,
rubriques.seq_rub AS rubrique,
rubriques.seq_caisse AS caisse_code_original,
CASE
WHEN sens_ecr_sal = 1 AND rad_cpt_compta_sal != 0 THEN rad_cpt_compta_sal
WHEN sens_ecr_pat = 1 AND rad_cpt_compta_pat != 0 THEN rad_cpt_compta_pat
ELSE null END AS compte_code_original,
-- sum(base) AS base,
-- sum(taux_sal) AS tx_sal,
-- sum(case when histo_lignes_bul.code_rub between '100' and '499' then res_sal else 0 end) AS brut,
-- sum(case when histo_lignes_bul.code_rub between '501' and '900' AND t_rubriques.code_calcul = 0 then res_sal else 0 end) AS mt_sal,
-- sum(res_pat * -1) AS mt_pat,
-- sum(taux_pat) AS tx_pat,
-- sum(case when histo_lignes_bul.code_rub between '100' and '499' or histo_lignes_bul.code_rub between '501' and '700' then res_sal else 0 end) AS net_imposable,
-- sum(case when histo_lignes_bul.code_rub between '100' and '499' or histo_lignes_bul.code_rub between '501' and '900' then res_sal else 0 end) AS net_a_payer,
-- sum(case when t_rubriques.code_calcul = 4 then res_sal else 0 end) AS av_nat,
-- sum(case when t_rubriques.code_calcul = 5 then res_sal else 0 end) AS od_sal,
t_rubriques.c_base
* case when @t_rubriques.c_base != 1 then coalesce(case when proratiser_conversion then bulletins.etp_contrat else 1.0 end, 1.0) else 1.0 end
* CASE WHEN p_base THEN (CASE s_base
WHEN 0 THEN base
WHEN 1 THEN base
WHEN 3 THEN res_sal
WHEN 5 THEN res_pat
END) else 0 end AS base,
t_rubriques.c_nombre
* case when @t_rubriques.c_nombre != 1 then coalesce(case when proratiser_conversion then bulletins.etp_contrat else 1.0 end, 1.0) else 1.0 end
* CASE WHEN p_nombre THEN (CASE s_nombre
WHEN 0 THEN base
WHEN 1 THEN base
WHEN 3 THEN res_sal
WHEN 5 THEN res_pat
END) else 0 end AS nombre,
t_rubriques.c_heures_contrat
* case when @t_rubriques.c_heures_contrat != 1 then coalesce(case when proratiser_conversion then bulletins.etp_contrat else 1.0 end, 1.0) else 1.0 end
* CASE WHEN p_heures_contrat
then (CASE s_heures_contrat
WHEN 0 THEN base
WHEN 1 THEN base
WHEN 3 THEN res_sal
WHEN 5 THEN res_pat
END)
else 0 end AS heure_contrat,
t_rubriques.c_heures_payees
* case when @t_rubriques.c_heures_payees != 1 then coalesce(case when proratiser_conversion then bulletins.etp_contrat else 1.0 end, 1.0) else 1.0 end
* CASE WHEN p_heures_payees
then (CASE s_heures_payees
WHEN 0 THEN base
WHEN 1 THEN base
WHEN 3 THEN res_sal
WHEN 5 THEN res_pat
END)
else 0 end AS heure_payee,
t_rubriques.c_heures_travaillees
* case when @t_rubriques.c_heures_travaillees != 1 then coalesce(case when proratiser_conversion then bulletins.etp_contrat else 1.0 end, 1.0) else 1.0 end
* CASE WHEN p_heures_travaillees
then (CASE s_heures_travaillees
WHEN 0 THEN base
WHEN 1 THEN base
WHEN 3 THEN res_sal
WHEN 5 THEN res_pat
END)
else 0 end AS heure_travaillee,
t_rubriques.c_masse_salariale *
CASE WHEN p_masse_salariale
THEN (CASE s_masse_salariale
WHEN 0 THEN base
WHEN 1 THEN base
WHEN 3 THEN res_sal
WHEN 5 THEN res_pat
END)
else 0 end AS montant_masse_salariale,
t_rubriques.c_brut *
CASE WHEN p_brut
THEN (CASE s_brut
WHEN 0 THEN base
WHEN 1 THEN base
WHEN 3 THEN res_sal
WHEN 5 THEN res_pat
END)
else 0 end AS montant_brut,
t_rubriques.c_frais_imposables *
case when p_frais_imposables
then (CASE s_frais_imposables
WHEN 0 THEN base
WHEN 1 THEN base
WHEN 3 THEN res_sal
WHEN 5 THEN res_pat
END)
else 0 end AS montant_frais_imposables,
t_rubriques.coefficient_txs *
case when p_cotisation_salarie
then taux_sal
else 0 end AS taux_cotisation_salarie,
t_rubriques.c_cotisation_salarie *
case when p_cotisation_salarie
then (CASE s_cotisation_salarie
WHEN 0 THEN base
WHEN 1 THEN base
WHEN 3 THEN res_sal
WHEN 5 THEN res_pat
END)
else 0 end AS montant_cotisation_salarie,
t_rubriques.coefficient_txp *
case when p_cotisation_patronale
then taux_pat
else 0 end AS taux_cotisation_patronale,
t_rubriques.c_cotisation_patronale *
case when p_cotisation_patronale
then (CASE s_cotisation_patronale
WHEN 0 THEN base
WHEN 1 THEN base
WHEN 3 THEN res_sal
WHEN 5 THEN res_pat
END)
else 0 end AS montant_cotisation_patronale,
t_rubriques.c_od_net_salarie *
CASE WHEN p_od_net_salarie
THEN (CASE s_od_net_salarie
WHEN 0 THEN base
WHEN 1 THEN base
WHEN 3 THEN res_sal
WHEN 5 THEN res_pat
END)
ELSE 0 END AS montant_od_net_salarie,
t_rubriques.c_od_net_patronale *
CASE WHEN p_od_net_patronale
THEN (CASE s_od_net_patronale
WHEN 0 THEN base
WHEN 1 THEN base
WHEN 3 THEN res_sal
WHEN 5 THEN res_pat
END)
ELSE 0 END AS montant_od_net_patronale,
t_rubriques.c_avantage_nature *
CASE WHEN p_avantage_nature
THEN (CASE s_avantage_nature
WHEN 0 THEN base
WHEN 1 THEN base
WHEN 3 THEN res_sal
WHEN 5 THEN res_pat
END)
ELSE 0 END AS montant_avantage_nature,
t_rubriques.c_net_imposable *
CASE WHEN p_net_imposable
THEN (CASE s_net_imposable
WHEN 0 THEN base
WHEN 1 THEN base
WHEN 3 THEN res_sal
WHEN 5 THEN res_pat
WHEN 6 THEN res_sal + res_pat
WHEN 7 THEN res_sal - res_pat
WHEN 8 THEN -res_sal + res_pat
END)
ELSE 0 END AS montant_net_imposable_salarie,
t_rubriques.c_net_a_payer *
CASE WHEN p_net_a_payer
THEN (CASE s_net_a_payer
WHEN 0 THEN base
WHEN 1 THEN base
WHEN 3 THEN res_sal
WHEN 5 THEN res_pat
END)
ELSE 0 END AS montant_net_a_payer_salarie,
t_rubriques.p_cumul,
t_rubriques.p_detail
from w_bulletins AS bulletins
join prod_qsp.histo_lignes_bul ON 1=1
AND histo_lignes_bul.seq_emploi = bulletins.seq_emploi
--AND case when histo_lignes_bul.NUM_BUL > 0 then histo_lignes_bul.NUM_BUL else @(histo_lignes_bul.NUM_BUL + 99999) end = bulletins.NUM_BUL
and histo_lignes_bul.num_bul = bulletins.num_bul
JOIN prod_qsp.rubriques ON rubriques.seq_rub = histo_lignes_bul.seq_rub
JOIN rh.t_rubriques on t_rubriques.code_original = rubriques.seq_rub
where false
OR t_rubriques.p_detail
OR t_rubriques.p_cumul
--GROUP BY 1,2,3,4,5,6,7,8
;
DROP TABLE IF EXISTS w_hp
;
CREATE TEMP TABLE w_hp AS
SELECT
w_hp_0.bul_id,
p_salaries.oid as salarie_id,
date_part('year', age(w_hp_0.date_debut, date_naissance)) AS age_id,
w_hp_0.matricule as sal_code_original,
w_hp_0.matricule,
w_hp_0.date_debut,
w_hp_0.date_fin,
w_hp_0.mois_paie as mois_activite,
w_hp_0.date_fin as date_paie,
w_hp_0.mois_paie,
rubrique_id,
coalesce(t_organismes_cotisation.oid, 0) as organisme_cotisation_id,
coalesce(t_compte.oid, 0) as compte_id,
base,
nombre,
heure_contrat,
heure_payee,
heure_travaillee,
montant_masse_salariale,
montant_brut,
montant_frais_imposables,
taux_cotisation_salarie,
montant_cotisation_salarie,
taux_cotisation_patronale,
montant_cotisation_patronale,
montant_od_net_salarie,
montant_od_net_patronale,
montant_avantage_nature,
montant_net_imposable_salarie,
montant_net_a_payer_salarie,
p_cumul,
p_detail,
(max(ARRAY[EXTRACT(EPOCH FROM p_contrats_mois.date_fin), p_contrats_mois.oid]))[2] AS contrat_mois_id,
(max(ARRAY[EXTRACT(EPOCH FROM p_contrats_mois.date_fin), p_contrats_mois.contrat_id]))[2] AS contrat_id,
(max(ARRAY[EXTRACT(EPOCH FROM p_contrats_mois.date_fin), p_contrats_mois.etablissement_id]))[2] as etablissement_id,
0::bigint as profil_id
FROM w_hp_0
JOIN rh.p_salaries ON p_salaries.matricule = w_hp_0.matricule
LEFT JOIN rh.t_organismes_cotisation ON t_organismes_cotisation.code_original = w_hp_0.caisse_code_original
LEFT JOIN rh.t_compte ON t_compte.code_original = w_hp_0.compte_code_original
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_0.date_debut, w_hp_0.date_fin)
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
;
-- Association avec le contrat précédent.
with toto as (
SELECT
w_hp.bul_id,
(max(array[extract(epoch from w_hp.date_fin), p_contrats_mois.contrat_id]))[2] as contrat_id,
(max(array[extract(epoch from w_hp.date_fin), p_contrats_mois.oid]))[2] as contrat_mois_id
from w_hp
join rh.p_contrats_mois on 1=1
and p_contrats_mois.salarie_id = w_hp.salarie_id
and p_contrats_mois.date_fin < w_hp.date_debut
where w_hp.contrat_mois_id is null
group by 1
)
UPDATE w_hp set
contrat_id = toto.contrat_id,
contrat_mois_id = toto.contrat_mois_id
from toto
where w_hp.bul_id = toto.bul_id
;
TRUNCATE rh.p_historique_paie
;
INSERT INTO rh.p_historique_paie(
code_original,
etablissement_id,
age_id,
contrat_id,
contrat_mois_id,
date_debut,
date_fin,
mois_activite,
date_paie,
mois_paie,
base,
nombre,
heure_contrat,
heure_payee,
heure_travaillee,
montant_masse_salariale,
montant_brut,
montant_avantage_nature,
montant_frais_imposables,
montant_cotisation_salarie,
montant_cotisation_patronale,
montant_od_net_salarie,
montant_od_net_patronale,
montant_net_imposable_salarie,
montant_net_a_payer_salarie,
taux_cotisation_salarie,
taux_cotisation_patronale,
organisme_cotisation_id,
profil_id,
rubrique_id,
compte_id,
salarie_id)
SELECT
w_hp.bul_id,
w_hp.etablissement_id,
w_hp.age_id,
w_hp.contrat_id,
w_hp.contrat_mois_id,
w_hp.date_debut,
w_hp.date_fin,
w_hp.mois_activite,
w_hp.date_paie,
w_hp.mois_paie,
w_hp.base,
w_hp.nombre,
w_hp.heure_contrat,
w_hp.heure_payee,
w_hp.heure_travaillee,
w_hp.montant_masse_salariale,
w_hp.montant_brut,
w_hp.montant_avantage_nature,
w_hp.montant_frais_imposables,
w_hp.montant_cotisation_salarie,
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,
w_hp.taux_cotisation_salarie,
w_hp.taux_cotisation_patronale,
w_hp.organisme_cotisation_id,
w_hp.profil_id,
w_hp.rubrique_id,
w_hp.compte_id,
w_hp.salarie_id
FROM w_hp
where p_detail
;
-- Création d'une table récapitulative des écarts à calculer par indicateur de paie (1 seule ligne).
DROP TABLE IF EXISTS w_cumul
;
CREATE TEMP TABLE w_cumul AS
SELECT
bool_or(p_cumul and p_heures_contrat) as total_heures_contrat,
bool_or(p_cumul and p_heures_payees) as total_heures_payees,
bool_or(p_cumul and p_heures_travaillees) as total_heures_travaillees,
bool_or(p_cumul and p_masse_salariale) as total_masse_salariale,
bool_or(p_cumul and p_brut) as total_brut,
bool_or(p_cumul and p_avantage_nature) as total_avantage_nature,
bool_or(p_cumul and p_frais_imposables) as total_frais_imposables,
bool_or(p_cumul and p_cotisation_salarie) as total_cotisation_salarie,
bool_or(p_cumul and p_cotisation_patronale) as total_cotisation_patronale,
bool_or(p_cumul and p_od_net_salarie) as total_od_net_salarie,
bool_or(p_cumul and p_od_net_patronale) as total_od_net_patronale,
bool_or(p_cumul and p_net_imposable) as total_net_imposable,
bool_or(p_cumul and p_net_a_payer) as total_net_a_payer
FROM rh.t_rubriques
;
-- Création d'une table temp qui regroupe tous les totaux à atteindre pour calculer l'écart
DROP TABLE IF EXISTS w_totaux
;
CREATE TEMP TABLE w_totaux AS
SELECT
w_hp.bul_id,
w_hp.etablissement_id,
w_hp.salarie_id,
w_hp.mois_paie,
sum(case when p_heures_contrat then heure_contrat else 0 end) as heure_contrat,
sum(case when p_heures_payees then heure_payee else 0 end) as heure_payee,
sum(case when p_heures_travaillees then heure_travaillee else 0 end) as heure_travaillee,
sum(case when p_masse_salariale then montant_masse_salariale else 0 end) as montant_masse_salariale,
sum(case when p_brut then montant_brut else 0 end) AS montant_brut,
sum(case when p_avantage_nature then montant_avantage_nature else 0 end) as montant_avantage_nature,
sum(case when p_frais_imposables then montant_frais_imposables else 0 end) as montant_frais_imposables,
sum(case when p_cotisation_salarie then montant_cotisation_salarie else 0 end) AS montant_cotisation_salarie,
sum(case when p_cotisation_patronale then montant_cotisation_patronale else 0 end) AS montant_cotisation_patronale,
sum(case when p_od_net_salarie then montant_od_net_salarie else 0 end) as montant_od_net_salarie,
sum(case when p_od_net_patronale then montant_od_net_patronale else 0 end) as montant_od_net_patronale,
sum(case when p_net_imposable then montant_net_imposable_salarie else 0 end) as montant_net_imposable_salarie,
sum(case when p_net_a_payer then montant_net_a_payer_salarie else 0 end) as montant_net_a_payer_salarie
FROM w_hp
JOIN rh.t_rubriques ON t_rubriques.oid = w_hp.rubrique_id
where w_hp.p_cumul
GROUP BY 1,2,3,4
;
-- Insérer pour chaque bulletin une ligne qui va faire le compte avec le total (rubrique 'C000' nommée 'Ecart cumulé')
INSERT INTO rh.p_historique_paie (
code_original,
etablissement_id,
age_id,
contrat_id,
contrat_mois_id,
date_debut,
date_fin,
date_paie,
mois_activite,
mois_paie,
base,
nombre,
heure_contrat,
heure_payee,
heure_travaillee,
montant_masse_salariale,
montant_brut,
montant_avantage_nature,
montant_frais_imposables,
montant_cotisation_salarie,
montant_cotisation_patronale,
montant_od_net_salarie,
montant_od_net_patronale,
montant_net_imposable_salarie,
montant_net_a_payer_salarie,
organisme_cotisation_id,
profil_id,
rubrique_id,
compte_id,
salarie_id,
taux_cotisation_patronale,
taux_cotisation_salarie)
WITH subq as (
SELECT
p_historique_paie.code_original as bul_id,
p_historique_paie.etablissement_id,
p_historique_paie.age_id,
p_historique_paie.contrat_id,
p_historique_paie.contrat_mois_id,
p_historique_paie.date_debut,
p_historique_paie.date_fin,
p_historique_paie.date_paie,
p_historique_paie.mois_activite,
p_historique_paie.mois_paie,
0 AS base,
0 AS nombre,
0 AS organisme_cotisation_id,
0 AS profil_id,
(SELECT oid FROM rh.t_rubriques WHERE code = 'C000') as rubrique_id,
0 AS compte_id,
salarie_id,
0 AS taux_cotisation_patronale,
0 AS taux_cotisation_salarie,
sum(heure_contrat) AS heure_contrat,
sum(heure_payee) AS heure_payee,
sum(heure_travaillee) AS heure_travaillee,
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 rh.p_historique_paie
GROUP BY 1,2,3,4,5,6,7,8,9,10,11,12,13,14,15,16,17,18
)
SELECT
subq.bul_id,
subq.etablissement_id,
subq.age_id,
subq.contrat_id,
subq.contrat_mois_id,
subq.date_debut,
subq.date_fin,
subq.date_paie,
subq.mois_activite,
subq.mois_paie,
subq.base,
subq.nombre,
case when total_heures_contrat then w_totaux.heure_contrat - subq.heure_contrat else 0 end as heure_contrat,
case when total_heures_payees then w_totaux.heure_payee - subq.heure_payee else 0 end as heure_payee,
case when total_heures_travaillees then w_totaux.heure_travaillee - subq.heure_travaillee else 0 end as heure_travaillee,
case when total_masse_salariale then w_totaux.montant_masse_salariale - subq.montant_masse_salariale else 0 end as montant_masse_salariale,
case when total_brut then w_totaux.montant_brut - subq.montant_brut else 0 end as montant_brut,
case when total_avantage_nature then w_totaux.montant_avantage_nature - subq.montant_avantage_nature else 0 end as montant_avantage_nature,
case when total_frais_imposables then w_totaux.montant_frais_imposables - subq.montant_frais_imposables else 0 end as montant_frais_imposables,
case when total_cotisation_salarie then w_totaux.montant_cotisation_salarie - subq.montant_cotisation_salarie else 0 end as montant_cotisation_salarie,
case when total_cotisation_patronale then w_totaux.montant_cotisation_patronale - subq.montant_cotisation_patronale else 0 end as montant_cotisation_patronale,
case when total_od_net_salarie then w_totaux.montant_od_net_salarie - subq.montant_od_net_salarie else 0 end as montant_od_net_salarie,
case when total_od_net_patronale then w_totaux.montant_od_net_patronale - subq.montant_od_net_patronale else 0 end as montant_od_net_patronale,
case when total_net_imposable then w_totaux.montant_net_imposable_salarie - subq.montant_net_imposable_salarie else 0 end as montant_net_imposable_salarie,
case when total_net_a_payer then w_totaux.montant_net_a_payer_salarie - subq.montant_net_a_payer_salarie else 0 end as montant_net_a_payer_salarie,
subq.organisme_cotisation_id AS organisme_cotisation_id,
subq.profil_id,
subq.rubrique_id,
subq.compte_id,
subq.salarie_id,
subq.taux_cotisation_patronale,
subq.taux_cotisation_salarie
FROM subq
JOIN w_totaux ON w_totaux.bul_id = subq.bul_id
JOIN w_cumul ON true
WHERE 1!=1
OR (total_heures_contrat AND w_totaux.heure_contrat - subq.heure_contrat != 0)
OR (total_heures_payees AND w_totaux.heure_payee - subq.heure_payee != 0)
OR (total_heures_travaillees AND w_totaux.heure_travaillee - subq.heure_travaillee != 0)
OR (total_masse_salariale AND w_totaux.montant_masse_salariale - subq.montant_masse_salariale != 0)
OR (total_brut AND w_totaux.montant_brut - subq.montant_brut != 0)
OR (total_avantage_nature AND w_totaux.montant_avantage_nature - subq.montant_avantage_nature != 0)
OR (total_frais_imposables AND w_totaux.montant_frais_imposables - subq.montant_frais_imposables != 0)
OR (total_cotisation_salarie AND w_totaux.montant_cotisation_salarie - subq.montant_cotisation_salarie != 0)
OR (total_cotisation_patronale AND w_totaux.montant_cotisation_patronale - subq.montant_cotisation_patronale != 0)
OR (total_od_net_salarie AND w_totaux.montant_od_net_salarie - subq.montant_od_net_salarie != 0)
OR (total_od_net_patronale AND w_totaux.montant_od_net_patronale - subq.montant_od_net_patronale != 0)
OR (total_net_imposable AND w_totaux.montant_net_imposable_salarie - subq.montant_net_imposable_salarie != 0)
OR (total_net_a_payer AND w_totaux.montant_net_a_payer_salarie - subq.montant_net_a_payer_salarie != 0)
;
SELECT base.cti_stash_pop_table_indexes('rh', 'p_historique_paie')
;
]]></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 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_contrats ON p_contrats.oid = p_contrats_mois.contrat_id
JOIN w_profils ON 1=1
AND w_profils.histo_emp_seq_emploi = p_contrats.numero_contrat
AND base.cti_overlaps(w_profils.date_debut, w_profils.date_fin, p_contrats_mois.date_debut, p_contrats_mois.date_fin)
GROUP BY 1,2,3,4,5
;
-- @TODO Calcul ETP théorique, Il faudra sans doute optimiser
DROP TABLE IF EXISTS maj_etp
;
CREATE TEMP TABLE maj_etp AS
SELECT
contrat_mois_id,
(CASE
WHEN type_temps_travail_id = 0 THEN 100
WHEN type_temps_travail_code = 'TC' THEN 100
ELSE substr(type_temps_travail_code,3)::numeric / 151.67 * 100
END)::numeric AS pct_temps_travail,
(date_fin - date_debut + 1)::numeric AS duree,
(CASE date_part('month',date_fin)
WHEN 02 THEN CASE WHEN date_part('year',date_fin) IN (2000,2004,2008,2012) THEN 29 ELSE 28 END
WHEN 04 THEN 30
WHEN 06 THEN 30
WHEN 09 THEN 30
WHEN 11 THEN 30
ELSE 31
END)::numeric AS duree_mois
FROM rh.p_contrats_mois
JOIN rh.p_profil_contrat_mois ON p_profil_contrat_mois.contrat_mois_id = p_contrats_mois.oid
JOIN rh.p_profils ON p_profils.oid = p_profil_contrat_mois.profil_id
;
UPDATE rh.p_contrats_mois
SET equivalent_temps_plein = round((duree / duree_mois) * (pct_temps_travail / 100), 7)
FROM maj_etp
WHERE 1=1
AND p_contrats_mois.oid = maj_etp.contrat_mois_id
AND equivalent_temps_plein IS DISTINCT FROM round((duree / duree_mois) * (pct_temps_travail / 100), 7)
;
-- correction temporaire des est_hors_periode à cause de la participation.
with toto as (
select p_contrats_mois.oid as hid, case when base.cti_overlaps(p_contrats.date_debut, p_contrats.date_fin, p_contrats_mois.date_debut, p_contrats_mois.date_fin) then 0 else 1 end as hors_pr
from rh.p_contrats_mois
join rh.p_contrats on p_contrats_mois.contrat_id = p_contrats.oid
--where p_contrats_mois.salarie_id = 84
--order by mois_activite desc
)
update rh.p_contrats_mois set
est_hors_periode = hors_pr
from toto
where toto.hid = p_contrats_mois.oid
and est_hors_periode is distinct from hors_pr
]]></sqlcmd>
</NODE>
<NODE label="Arrêts de travail">
<sqlcmd><![CDATA[
-- Création d'une table temporaire
DROP TABLE IF EXISTS w_arrets
;
CREATE TEMP TABLE w_arrets AS
SELECT
seq_absence,
absence.seq_emploi AS numero_contrat,
to_char(datedeb, 'YYYYMM')::numeric AS mois,
datedeb::date AS date_debut,
CASE WHEN datefin::date = '4000-01-01'::date THEN '2099-12-31'::date ELSE datefin::date END AS date_fin,
(CASE WHEN datefin::date = '4000-01-01'::date THEN current_date ELSE datefin::date END) - datedeb::date + 1 AS nb_jours,
seq_nat_abs AS motif,
num_sal AS matricule
FROM prod_qsp.absence
JOIN prod_qsp.emplois ON 1=1
AND absence.seq_emploi = emplois.seq_emploi
WHERE 1=1
GROUP BY 1,2,3,4,5,6,7,8
;
-- Alimentation des arrêts de travail
TRUNCATE rh.p_arrets_travail
;
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,
p_contrats.oid,
w_arrets.mois,
w_arrets.date_debut,
w_arrets.date_fin,
CASE WHEN w_arrets.date_fin = '2099-12-31'::date THEN '2099-12-31'::date ELSE (w_arrets.date_fin + INTERVAL '1 day')::date END AS date_reprise,
t_motifs_arret.oid AS motif_arret_id,
0 AS precision_motif_arret_id,
w_arrets.nb_jours
FROM w_arrets
JOIN rh.p_salaries ON p_salaries.matricule = w_arrets.matricule
JOIN rh.t_motifs_arret ON t_motifs_arret.code_original = w_arrets.motif
JOIN rh.p_contrats ON p_contrats.numero_contrat = w_arrets.numero_contrat
;
-- Ventilation mensuelle des arrêts de travail
TRUNCATE rh.p_arrets_travail_mois
;
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
p_arrets_travail.oid AS arret_travail_id,
p_arrets_travail.salarie_id AS salarie_id,
p_arrets_travail.contrat_id AS contrat_id,
(max(DISTINCT ARRAY[p_contrats_mois.date_fin - p_contrats_mois.date_debut, p_contrats_mois.oid]))[2] AS contrat_mois_id, -- On ratache l'arrêt au contrat le plus long dans le mois lorsque plusieurs contrat sur la même période.
p_contrats_mois.mois_activite,
CASE WHEN p_arrets_travail.date_debut BETWEEN min(p_contrats_mois.date_debut) AND max(p_contrats_mois.date_fin) THEN 1 ELSE 0 END AS nombre_debut_arret,
CASE WHEN p_arrets_travail.date_fin BETWEEN min(p_contrats_mois.date_debut) AND max(p_contrats_mois.date_fin) THEN 1 ELSE 0 END AS nombre_fin_arret,
0 AS nb_reprise_apres_arret,
min(GREATEST(p_contrats_mois.date_debut, p_arrets_travail.date_debut)) AS date_debut,
max(LEAST(p_contrats_mois.date_fin, p_arrets_travail.date_fin)) AS date_fin,
max(LEAST(p_contrats_mois.date_fin, p_arrets_travail.date_fin)::date) - min(GREATEST(p_contrats_mois.date_debut, p_arrets_travail.date_debut)::date) + 1 AS nb_jours,
1
FROM rh.p_contrats_mois
JOIN rh.p_arrets_travail ON 1=1
AND p_contrats_mois.contrat_id = p_arrets_travail.contrat_id
AND p_arrets_travail.date_debut <= p_contrats_mois.date_fin
AND p_arrets_travail.date_fin >= p_contrats_mois.date_debut
GROUP BY 1,2,3,5,p_arrets_travail.date_debut,p_arrets_travail.date_fin,p_arrets_travail.date_reprise
ORDER BY p_contrats_mois.mois_activite desc
;
update rh.p_arrets_travail_mois
set nb_reprise_apres_arret = subq.nb_reprise_apres_arret
from (
select
t1.arret_travail_id,
t1.mois_activite,
min(case when p_arrets_travail.date_reprise between t2.date_debut and t2.date_fin then 0 else 1 end) as nb_reprise_apres_arret
from rh.p_arrets_travail_mois as t1
join rh.p_arrets_travail ON p_arrets_travail.oid = t1.arret_travail_id
left join rh.p_arrets_travail_mois as t2 ON 1=1
AND t1.salarie_id = t2.salarie_id
AND t1.date_debut != t2.date_debut
AND t1.date_fin != t2.date_fin
GROUP BY t1.arret_travail_id, t1.mois_activite
order by 2 desc
) as subq
where 1=1
and p_arrets_travail_mois.arret_travail_id = subq.arret_travail_id
and p_arrets_travail_mois.mois_activite = subq.mois_activite
;
]]></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>