<?xml version="1.0" encoding="ISO-8859-1"?>
|
|
<ROOT>
|
|
<NODE name="INIT" label="INITIALISATIONS">
|
|
<NODE label="Pre-traitements des tables prestataire">
|
|
<sqlcmd><![CDATA[
|
|
|
|
-- Utilisation de vues pour les tables ayant des dates sous forme d'entiers.
|
|
DROP VIEW IF EXISTS prod_ccmx.v_salarie
|
|
;
|
|
|
|
CREATE OR REPLACE VIEW prod_ccmx.v_salarie AS
|
|
SELECT
|
|
to_timestamp((sal_dnaiss - 25567) * 86400)::date AS v_sal_dnaiss,
|
|
to_timestamp((sal_dat_cemp - 25567) * 86400)::date AS v_sal_dat_cemp,
|
|
*
|
|
FROM prod_ccmx.salarie
|
|
;
|
|
|
|
DROP VIEW IF EXISTS prod_ccmx.v_h_cnt_trav
|
|
;
|
|
|
|
CREATE OR REPLACE VIEW prod_ccmx.v_h_cnt_trav AS
|
|
SELECT
|
|
to_timestamp((cnt_date - 25567) * 86400)::date AS date_debut,
|
|
CASE WHEN cnt_fin = 0 THEN '2099-12-31'::date ELSE to_timestamp((cnt_fin - 25567) * 86400)::date END AS date_fin,
|
|
*
|
|
FROM prod_ccmx.h_cnt_trav
|
|
;
|
|
|
|
DROP TABLE IF EXISTS w_cnt
|
|
;
|
|
|
|
CREATE TEMP TABLE w_cnt AS
|
|
SELECT
|
|
sal_matr||'-'||cnt_id||'-'||rank() OVER (PARTITION BY sal_matr order by cnt_date) AS numero_contrat,
|
|
date_fin - date_debut + 1 AS duree,
|
|
*
|
|
FROM prod_ccmx.v_h_cnt_trav
|
|
;
|
|
|
|
-- #correction : si date_fin < date_debut alors date_fin = '2099-12-31'
|
|
UPDATE w_cnt
|
|
SET
|
|
date_fin = '2099-12-31'::date,
|
|
duree = '2099-12-31'::date - date_debut + 1
|
|
WHERE date_fin < date_debut
|
|
;
|
|
|
|
DROP VIEW IF EXISTS prod_ccmx.v_h_contrat
|
|
;
|
|
|
|
CREATE OR REPLACE VIEW prod_ccmx.v_h_contrat AS
|
|
SELECT
|
|
to_timestamp((con_du - 25567) * 86400)::date AS date_debut,
|
|
CASE WHEN con_au = 0 THEN '2099-12-31'::date ELSE to_timestamp((con_au - 25567) * 86400)::date END AS date_fin,
|
|
*
|
|
FROM prod_ccmx.h_contrat
|
|
;
|
|
|
|
DROP VIEW IF EXISTS prod_ccmx.v_bulletin
|
|
;
|
|
|
|
CREATE OR REPLACE VIEW prod_ccmx.v_bulletin AS
|
|
SELECT
|
|
to_timestamp((bul_deb - 25567) * 86400)::date AS date_debut,
|
|
to_timestamp((bul_fin - 25567) * 86400)::date AS date_fin,
|
|
to_timestamp((bul_pai - 25567) * 86400)::date AS date_paie,
|
|
*
|
|
FROM prod_ccmx.bulletin
|
|
WHERE bul_pai > 39811
|
|
;
|
|
|
|
DROP VIEW IF EXISTS prod_ccmx.v_h_coeff
|
|
;
|
|
|
|
CREATE OR REPLACE VIEW prod_ccmx.v_h_coeff AS
|
|
SELECT
|
|
to_timestamp((coe_du - 25567) * 86400)::date AS date_debut,
|
|
CASE WHEN coe_au = 0 THEN '2099-12-31'::date ELSE to_timestamp((coe_au - 25567) * 86400)::date END AS date_fin,
|
|
*
|
|
FROM prod_ccmx.h_coeff
|
|
;
|
|
|
|
DROP VIEW IF EXISTS prod_ccmx.v_h_es
|
|
;
|
|
|
|
CREATE OR REPLACE VIEW prod_ccmx.v_h_es AS
|
|
SELECT
|
|
to_timestamp((e_s_date - 25567) * 86400)::date AS date_debut,
|
|
CASE WHEN e_s_dates = 0 THEN '2099-12-31'::date ELSE to_timestamp((e_s_dates - 25567) * 86400)::date END AS date_fin,
|
|
*
|
|
FROM prod_ccmx.h_es
|
|
;
|
|
|
|
]]></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 ent_id, ent_rais, substr(ent_rais, 1, 50), ent_id
|
|
FROM prod_ccmx.societe
|
|
WHERE ent_id 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 eta_id, eta_rais, substr(eta_rais, 1, 50), eta_id, t_entreprises.oid
|
|
FROM prod_ccmx.etablt
|
|
JOIN rh.t_entreprises ON t_entreprises.code_original = ent_id
|
|
WHERE eta_id NOT IN (SELECT code_original FROM rh.t_etablissements)
|
|
GROUP BY 1,2,3,4,5
|
|
;
|
|
|
|
-- Màj des catégories socio-professionnelles.
|
|
INSERT INTO rh.t_categories_socio_professionnelle(code, code_original, texte, texte_court)
|
|
SELECT lower(ins_id), lower(ins_id), lower(ins_id), substr(lower(ins_id), 1, 50)
|
|
FROM prod_ccmx.h_insee_emp
|
|
WHERE lower(ins_id) NOT IN (SELECT code_original FROM rh.t_categories_socio_professionnelle)
|
|
GROUP BY 1,2,3,4
|
|
;
|
|
|
|
-- Màj des groupes cotisants : code 'PTG' ?
|
|
|
|
-- Màj des motifs de début de contrat
|
|
INSERT INTO rh.t_motifs_debut_contrat(code, code_original, texte, texte_court)
|
|
SELECT mes_id, mes_id, mes_id, substr(mes_id, 1, 50)
|
|
FROM prod_ccmx.v_h_es
|
|
WHERE 1=1
|
|
AND mes_id NOT IN (SELECT code_original FROM rh.t_motifs_debut_contrat)
|
|
AND length(trim(mes_id)) > 0
|
|
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 mes_ids||motif_id, mes_ids||motif_id, mes_ids||motif_id, substr(mes_ids||motif_id, 1, 50)
|
|
FROM prod_ccmx.v_h_es
|
|
WHERE 1=1
|
|
AND mes_ids||motif_id NOT IN (SELECT code_original FROM rh.t_motifs_fin_contrat)
|
|
AND length(trim(mes_ids)) > 0
|
|
GROUP BY 1,2,3,4
|
|
;
|
|
|
|
-- Màj des nationalités
|
|
INSERT INTO rh.t_nationalites(code, texte, texte_court, code_original)
|
|
SELECT sal_cod_pays, sal_cod_pays, substr(sal_cod_pays,1,50), sal_cod_pays
|
|
FROM prod_ccmx.v_salarie
|
|
WHERE sal_cod_pays NOT IN (SELECT code_original FROM rh.t_nationalites)
|
|
GROUP BY 1,2,3,4
|
|
;
|
|
|
|
-- Màj des organismes de cotisation
|
|
|
|
-- Màj des qualifications (ATTENTION aux jointures : code sur 3 mais dans les tables de faits, sur 2 et 3)
|
|
|
|
-- Màj des rubriques
|
|
INSERT INTO rh.t_rubriques(code, texte, texte_court, code_original, rang_edition)
|
|
SELECT
|
|
pla_id,
|
|
max(pla_int),
|
|
max(substr(pla_int, 1, 50)),
|
|
pla_id,
|
|
max(pla_type::numeric) -- @TODO NOT SURE => reg_id ?
|
|
FROM prod_ccmx.plap
|
|
WHERE 1=1
|
|
AND pla_id NOT IN (SELECT code_original FROM rh.t_rubriques)
|
|
GROUP BY 1,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 (non profil)
|
|
INSERT INTO rh.t_situations_famille(code, texte, texte_court, code_original)
|
|
SELECT fam_id, fam_id, substr(fam_id, 1, 50), fam_id
|
|
FROM prod_ccmx.v_salarie
|
|
WHERE 1=1
|
|
AND fam_id 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 ctr_id, ctr_id, ctr_id, substr(ctr_id,1,50)
|
|
FROM prod_ccmx.v_h_contrat
|
|
WHERE 1=1
|
|
AND ctr_id 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 cat_id, cat_id, cat_lib, substr(cat_lib, 1, 50)
|
|
FROM prod_ccmx.ar_categ
|
|
WHERE 1=1
|
|
AND cat_id 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 cem_id, cem_id, cem_id, substr(cem_id, 1, 50)
|
|
FROM prod_ccmx.h_cemploi
|
|
WHERE 1=1
|
|
AND cem_id NOT IN (SELECT code_original FROM rh.t_types_temps_travail)
|
|
GROUP BY 1,2,3,4
|
|
UNION
|
|
SELECT
|
|
cem_id::text||coalesce(tem_taux::text, ''),
|
|
cem_id::text||coalesce(tem_taux::text, ''),
|
|
cem_id::text||coalesce(tem_taux::text, ''),
|
|
substr(cem_id::text||coalesce(tem_taux::text, ''), 1, 50)
|
|
FROM prod_ccmx.h_cemploi
|
|
left join prod_ccmx.h_tempart ON 1=1
|
|
WHERE 1=1
|
|
AND cem_id::text||coalesce(tem_taux::text, '') 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 hth_id, hth_id, hth_id, substr(hth_id, 1, 50)
|
|
FROM prod_ccmx.h_typ_hor
|
|
WHERE 1=1
|
|
AND hth_id NOT IN (SELECT code_original FROM rh.t_types_horaire)
|
|
GROUP BY 1,2,3,4
|
|
;
|
|
|
|
-- Màj des services
|
|
|
|
-- Màj des spécialités
|
|
|
|
-- Màj des codes emploi
|
|
INSERT INTO rh.t_codes_emploi(code_original, code, texte, texte_court)
|
|
SELECT emp_id, emp_id, emp_lib, substr(emp_lib, 1, 50)
|
|
FROM prod_ccmx.ar_emploi
|
|
WHERE 1=1
|
|
AND emp_id NOT IN (SELECT code_original FROM rh.t_codes_emploi)
|
|
GROUP BY 1,2,3,4
|
|
;
|
|
|
|
-- Màj des comptes.
|
|
INSERT INTO rh.t_compte(code_original, code, texte, texte_court)
|
|
SELECT cpt_cle, substr(cpt_cpt1, 2, 6), cpt_lib, substr(cpt_lib, 1, 50)
|
|
FROM prod_ccmx.ar_compte
|
|
WHERE 1=1
|
|
AND length(trim(cpt_lib)) > 0
|
|
AND cpt_cle NOT IN (SELECT code_original FROM rh.t_compte WHERE code_original IS NOT NULL)
|
|
GROUP BY 1,2,3,4
|
|
;
|
|
|
|
-- [NON] Màj des sociétés d'interim
|
|
|
|
-- Màj des grilles
|
|
INSERT INTO rh.t_grilles(code_original, code, texte, texte_court)
|
|
SELECT coe_val, coe_val, coe_val, coe_val
|
|
FROM prod_ccmx.v_h_coeff
|
|
WHERE 1=1
|
|
AND coe_val NOT IN (SELECT code_original FROM rh.t_grilles)
|
|
GROUP BY 1
|
|
;
|
|
|
|
-- [NON] Màj des groupes de grilles
|
|
|
|
-- [NON] Màj des motifs d'arret
|
|
|
|
-- [NON] Màj des précisions du motif d'arrêt
|
|
|
|
-- [NON] Màj des motifs de visite médicale
|
|
|
|
-- [NON] Màj des circonstances d'accident du travail
|
|
|
|
-- [NON] Màj des lieux d'accident du travail
|
|
|
|
-- [NON] Màj de la nature de l'accident du travail
|
|
|
|
-- [NON] Màj des sièges d'accident du travail
|
|
|
|
-- [NON] Màj des listes de formations
|
|
|
|
-- [NON] Màj des sections analytiques compta
|
|
|
|
-- [NON] Màj des sections analytiques paie
|
|
|
|
]]></sqlcmd>
|
|
</NODE>
|
|
</NODE>
|
|
<NODE name="PROD" label="RECUPERATION DES DONNEES DE PRODUCTION">
|
|
<NODE label="Chiffrier">
|
|
<sqlcmd><![CDATA[
|
|
|
|
TRUNCATE rh.p_chiffrier_production
|
|
;
|
|
|
|
INSERT INTO rh.p_chiffrier_production (entreprise_id, etablissement_id, mois, nombre_salaries, montant_brut, nombre_heures)
|
|
select
|
|
0 AS entreprise_id,
|
|
0 as etablissement_id,
|
|
substr(bulletin.bul_id, 1, 6)::numeric AS mois,
|
|
count(distinct bulletin.sal_matr) AS nombre_salaries,
|
|
sum(lig_mont1) AS montant_brut,
|
|
sum(lig_bas1) AS nombre_heures
|
|
from prod_ccmx.v_bulletin AS bulletin
|
|
join prod_ccmx.ligne ON ligne.bul_id = bulletin.bul_id
|
|
where 1=1
|
|
AND pla_id IN ('BRUT', '4540', '1365')
|
|
and bul_type = 'V' -- on ne conserve que les bulletins corrects.
|
|
and bulletin.eta_id = '0001'
|
|
group by 1,2,3
|
|
;
|
|
|
|
]]></sqlcmd>
|
|
</NODE>
|
|
<NODE label="Pre-traitement des Profils">
|
|
<sqlcmd><![CDATA[
|
|
|
|
-- Ventilation des statuts.
|
|
DROP TABLE IF EXISTS w_h_categ
|
|
;
|
|
|
|
CREATE TEMP TABLE w_h_categ AS
|
|
select
|
|
max(t1.cat_id) AS cat_id,
|
|
t1.sal_matr,
|
|
t1.hca_date,
|
|
max(to_timestamp((t1.hca_date - 25567) * 86400)::date) AS date_debut,
|
|
min(coalesce(to_timestamp((t2.hca_date - 25567) * 86400)::date - '1 day'::interval, '2099-12-31')) AS date_fin
|
|
from prod_ccmx.h_categ as t1
|
|
left join prod_ccmx.h_categ AS t2 ON 1=1
|
|
and t1.sal_matr = t2.sal_matr
|
|
and t1.hca_date < t2.hca_date
|
|
group by 2,3
|
|
;
|
|
|
|
CREATE INDEX w_h_categ_1 ON w_h_categ USING btree (sal_matr)
|
|
;
|
|
CREATE INDEX w_h_categ_2 ON w_h_categ USING btree (cat_id)
|
|
;
|
|
CREATE INDEX w_h_categ_3 ON w_h_categ USING btree (date_debut)
|
|
;
|
|
CREATE INDEX w_h_categ_4 ON w_h_categ USING btree (date_fin)
|
|
;
|
|
|
|
-- Ventilation des categorie_socio_professionnelle.
|
|
DROP TABLE IF EXISTS w_h_insee_emp
|
|
;
|
|
|
|
CREATE TEMP TABLE w_h_insee_emp AS
|
|
select
|
|
max (t1.ins_id) AS ins_id,
|
|
t1.sal_matr,
|
|
t1.hie_date,
|
|
max(to_timestamp((t1.hie_date - 25567) * 86400)::date) AS date_debut,
|
|
min(coalesce(to_timestamp((t2.hie_date - 25567) * 86400)::date - '1 day'::interval, '2099-12-31')) AS date_fin
|
|
from prod_ccmx.h_insee_emp as t1
|
|
left join prod_ccmx.h_insee_emp AS t2 ON 1=1
|
|
and t1.sal_matr = t2.sal_matr
|
|
and t1.hie_date < t2.hie_date
|
|
group by 2,3
|
|
;
|
|
|
|
CREATE INDEX w_h_insee_emp_1 ON w_h_insee_emp USING btree (sal_matr)
|
|
;
|
|
CREATE INDEX w_h_insee_emp_2 ON w_h_insee_emp USING btree (ins_id)
|
|
;
|
|
CREATE INDEX w_h_insee_emp_3 ON w_h_insee_emp USING btree (date_debut)
|
|
;
|
|
CREATE INDEX w_h_insee_emp_4 ON w_h_insee_emp USING btree (date_fin)
|
|
;
|
|
|
|
-- Ventilation des code_emploi.
|
|
DROP TABLE IF EXISTS w_h_emploi
|
|
;
|
|
|
|
CREATE TEMP TABLE w_h_emploi AS
|
|
select
|
|
max(t1.emp_id) AS emp_id,
|
|
t1.sal_matr,
|
|
t1.hem_date,
|
|
max(to_timestamp((t1.hem_date - 25567) * 86400)::date) AS date_debut,
|
|
min(coalesce(to_timestamp((t2.hem_date - 25567) * 86400)::date - '1 day'::interval, '2099-12-31')) AS date_fin
|
|
from prod_ccmx.h_emploi as t1
|
|
left join prod_ccmx.h_emploi AS t2 ON 1=1
|
|
and t1.sal_matr = t2.sal_matr
|
|
and t1.hem_date < t2.hem_date
|
|
group by 2,3
|
|
;
|
|
|
|
CREATE INDEX w_h_emploi_1 ON w_h_emploi USING btree (sal_matr)
|
|
;
|
|
CREATE INDEX w_h_emploi_2 ON w_h_emploi USING btree (emp_id)
|
|
;
|
|
CREATE INDEX w_h_emploi_3 ON w_h_emploi USING btree (date_debut)
|
|
;
|
|
CREATE INDEX w_h_emploi_4 ON w_h_emploi USING btree (date_fin)
|
|
;
|
|
|
|
-- Ventilation des types de temps de travail.
|
|
DROP TABLE IF EXISTS w_h_cemploi
|
|
;
|
|
|
|
CREATE TEMP TABLE w_h_cemploi AS
|
|
select
|
|
max(t1.cem_id) AS cem_id,
|
|
t1.sal_matr,
|
|
t1.hce_date,
|
|
max(to_timestamp((t1.hce_date - 25567) * 86400)::date) AS date_debut,
|
|
min(coalesce(to_timestamp((t2.hce_date - 25567) * 86400)::date - '1 day'::interval, '2099-12-31')) AS date_fin
|
|
from prod_ccmx.h_cemploi as t1
|
|
left join prod_ccmx.h_cemploi AS t2 ON 1=1
|
|
and t1.sal_matr = t2.sal_matr
|
|
and t1.hce_date < t2.hce_date
|
|
group by 2,3
|
|
;
|
|
|
|
CREATE INDEX w_h_cemploi_1 ON w_h_cemploi USING btree (sal_matr)
|
|
;
|
|
CREATE INDEX w_h_cemploi_2 ON w_h_cemploi USING btree (cem_id)
|
|
;
|
|
CREATE INDEX w_h_cemploi_3 ON w_h_cemploi USING btree (date_debut)
|
|
;
|
|
CREATE INDEX w_h_cemploi_4 ON w_h_cemploi USING btree (date_fin)
|
|
;
|
|
|
|
-- Ventilation des % des types de temps de travail partiel.
|
|
DROP TABLE IF EXISTS w_h_tempart
|
|
;
|
|
|
|
CREATE TEMP TABLE w_h_tempart AS
|
|
select
|
|
max(t1.tem_taux) AS tem_taux,
|
|
t1.sal_matr,
|
|
t1.tem_date,
|
|
max(to_timestamp((t1.tem_date - 25567) * 86400)::date) AS date_debut,
|
|
min(coalesce(to_timestamp((t2.tem_date - 25567) * 86400)::date - '1 day'::interval, '2099-12-31')) AS date_fin
|
|
from prod_ccmx.h_tempart as t1
|
|
left join prod_ccmx.h_tempart AS t2 ON 1=1
|
|
and t1.sal_matr = t2.sal_matr
|
|
and t1.tem_date < t2.tem_date
|
|
group by 2,3
|
|
;
|
|
|
|
CREATE INDEX w_h_tempart_1 ON w_h_tempart USING btree (sal_matr)
|
|
;
|
|
CREATE INDEX w_h_tempart_2 ON w_h_tempart USING btree (tem_taux)
|
|
;
|
|
CREATE INDEX w_h_tempart_3 ON w_h_tempart USING btree (date_debut)
|
|
;
|
|
CREATE INDEX w_h_tempart_4 ON w_h_tempart USING btree (date_fin)
|
|
;
|
|
|
|
-- Croisement de tous les historiques salariés jour par jour.
|
|
DROP TABLE IF EXISTS w_tmp_1
|
|
;
|
|
|
|
CREATE TEMP TABLE w_tmp_1 AS
|
|
SELECT
|
|
mat,
|
|
mois,
|
|
min(date_debut) AS date_debut,
|
|
max(date_fin) AS date_fin,
|
|
numero_contrat,
|
|
bul_id,
|
|
est_hors_periode,
|
|
type_contrat_code_original,
|
|
categorie_socio_professionnelle_code_original,
|
|
code_emploi_code_original,
|
|
statut_code_original,
|
|
grille_code_original,
|
|
type_temps_travail_code_original,
|
|
motif_debut_code_original,
|
|
motif_fin_code_original
|
|
FROM (
|
|
SELECT
|
|
salarie.sal_matr as mat,
|
|
cal.mois,
|
|
cal.date as date_debut,
|
|
cal.date as date_fin,
|
|
cnt.numero_contrat,
|
|
bul.bul_id,
|
|
CASE WHEN cnt.numero_contrat IS NULL THEN 1 ELSE 0 END est_hors_periode, -- paie hors période de contrat
|
|
coalesce(tcnt.ctr_id, chr(1)||'*') AS type_contrat_code_original,
|
|
coalesce(lower(ins.ins_id), chr(1)||'*') AS categorie_socio_professionnelle_code_original,
|
|
coalesce(emp.emp_id, chr(1)||'*') AS code_emploi_code_original,
|
|
coalesce(statut.cat_id, chr(1)||'*') AS statut_code_original,
|
|
coalesce(grille.coe_val, chr(1)||'*') AS grille_code_original,
|
|
coalesce(ttt.cem_id::text||coalesce(ptt.tem_taux::text, ''), chr(1)||'*') AS type_temps_travail_code_original,
|
|
coalesce(mes.mes_id, chr(1)||'*') AS motif_debut_code_original,
|
|
coalesce(mes.mes_ids||mes.motif_id, chr(1)||'*') AS motif_fin_code_original
|
|
from base.p_calendrier AS cal
|
|
cross join prod_ccmx.salarie
|
|
left join w_cnt AS cnt ON 1=1
|
|
AND cnt.sal_matr = salarie.sal_matr
|
|
AND date between cnt.date_debut and cnt.date_fin
|
|
left join prod_ccmx.v_bulletin AS bul ON 1=1
|
|
AND bul.sal_matr = salarie.sal_matr
|
|
AND date between bul.date_debut and bul.date_fin
|
|
left join prod_ccmx.v_h_contrat AS tcnt ON 1=1 -- type de contrat
|
|
AND tcnt.sal_matr = salarie.sal_matr
|
|
AND date between tcnt.date_debut and tcnt.date_fin
|
|
left join w_h_insee_emp as ins on 1=1 -- categorie_socio_professionnelle
|
|
AND ins.sal_matr = salarie.sal_matr
|
|
AND date between ins.date_debut and ins.date_fin
|
|
left join w_h_emploi as emp on 1=1 -- code_emploi
|
|
AND emp.sal_matr = salarie.sal_matr
|
|
AND date between emp.date_debut and emp.date_fin
|
|
left join w_h_categ as statut on 1=1 -- statut
|
|
AND statut.sal_matr = salarie.sal_matr
|
|
AND date between statut.date_debut and statut.date_fin
|
|
left join prod_ccmx.v_h_coeff as grille on 1=1 -- grille
|
|
AND grille.sal_matr = salarie.sal_matr
|
|
AND date between grille.date_debut and grille.date_fin
|
|
left join prod_ccmx.v_h_es as mes on 1=1 -- modes d'entrée/sortie
|
|
AND mes.sal_matr = salarie.sal_matr
|
|
AND date between mes.date_debut and mes.date_fin
|
|
left join w_h_cemploi as ttt on 1=1 -- type temps de travail
|
|
AND ttt.sal_matr = salarie.sal_matr
|
|
AND date between ttt.date_debut and ttt.date_fin
|
|
left join w_h_tempart as ptt on 1=1 -- type temps de travail : pourcentage pour les partiels
|
|
AND ptt.sal_matr = salarie.sal_matr
|
|
AND date between ptt.date_debut and ptt.date_fin
|
|
WHERE bul_type = 'V'
|
|
GROUP BY 1,2,3,4,5,6,7,8,9,10,11,12,13,14,15, mes.sal_matr, salarie.ins_id, salarie.emp_id, ins.ins_id, emp.emp_id, ptt.tem_taux ,ttt.cem_id, cnt.sal_matr, tcnt.sal_matr, statut.sal_matr, bul.sal_matr, grille.sal_matr
|
|
having 1!=1
|
|
OR cnt.sal_matr is not null
|
|
OR bul.sal_matr is not null) AS subq
|
|
GROUP BY 1,2,5,6,7,8,9,10,11,12,13,14,15
|
|
;
|
|
|
|
-- Association des bulletins de paie au dernier contrat connu lorsque hors période.
|
|
UPDATE w_tmp_1
|
|
SET numero_contrat = subq.numero_contrat
|
|
FROM (
|
|
select
|
|
t1.bul_id,
|
|
t1.mat,
|
|
(max(array[t2.date_debut::text, t2.numero_contrat::text]))[2] as numero_contrat
|
|
from w_tmp_1 AS t1
|
|
left join w_tmp_1 AS t2 ON 1=1
|
|
and t1.mat = t2.mat
|
|
and t1.bul_id != t2.bul_id
|
|
and t1.date_debut > t2.date_fin
|
|
where 1=1
|
|
and t1.numero_contrat is null
|
|
and t2.numero_contrat is not null
|
|
group by 1,2
|
|
) AS subq
|
|
WHERE 1=1
|
|
AND w_tmp_1.mat = subq.mat
|
|
AND w_tmp_1.bul_id = subq.bul_id
|
|
;
|
|
|
|
-- #correction Association des bulletins de paie au futur contrat connu.
|
|
UPDATE w_tmp_1
|
|
SET numero_contrat = subq.numero_contrat
|
|
FROM (
|
|
select
|
|
t1.bul_id,
|
|
t1.mat,
|
|
(min(array[t2.date_debut::text, t2.numero_contrat::text]))[2] as numero_contrat
|
|
from w_tmp_1 AS t1
|
|
left join w_tmp_1 AS t2 ON 1=1
|
|
and t1.mat = t2.mat
|
|
and t1.bul_id != t2.bul_id
|
|
and t1.date_fin < t2.date_debut
|
|
where 1=1
|
|
and t1.numero_contrat is null
|
|
and t2.numero_contrat is not null
|
|
group by 1,2
|
|
) AS subq
|
|
WHERE 1=1
|
|
AND w_tmp_1.mat = subq.mat
|
|
AND w_tmp_1.bul_id = subq.bul_id
|
|
;
|
|
|
|
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 permettant le matching du profil CTI au données Cegid
|
|
bul_id,
|
|
numero_contrat,
|
|
mat AS matricule,
|
|
min(date_debut) AS date_debut,
|
|
max(date_fin) AS date_fin,
|
|
est_hors_periode,
|
|
|
|
-- Données du Profil CTI
|
|
categorie_socio_professionnelle_code_original,
|
|
code_emploi_code_original,
|
|
grille_code_original AS grille_code_original,
|
|
chr(1)||'*' AS grille_groupe_code_original,
|
|
chr(1)||'*' AS groupe_cotisant_code_original,
|
|
motif_debut_code_original AS motif_debut_code_original,
|
|
motif_fin_code_original AS motif_fin_code_original,
|
|
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,
|
|
chr(1)||'*' AS societe_interim_code_original,
|
|
chr(1)||'*' AS specialite_code_original,
|
|
statut_code_original AS statut_code_original,--greatest(hst.phs_dadscat, chr(1)||'*') AS statut_code_original,
|
|
type_contrat_code_original AS type_contrat_code_original,
|
|
chr(1)||'*' AS type_horaire_code_original,
|
|
type_temps_travail_code_original AS type_temps_travail_code_original,--greatest(hst.phs_condemploi||phs_ttauxpartiel::float, chr(1)||'*') AS 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_tmp_1
|
|
GROUP BY 1,2,3,4,5,8,9,10,11,12,13,14,15,16,17,18,19,20,21,22,23,24,25,26,27,28,29,30
|
|
;
|
|
|
|
]]></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,
|
|
CASE WHEN length(trim(sal_val_nom)) > 0 THEN sal_val_nom ELSE sal_naiss END AS nom,
|
|
sal_prenom AS prenom,
|
|
v_sal_dnaiss AS date_naissance,
|
|
CASE WHEN substr(sal_noss, 1, 1) = 1 THEN 'M' ELSE 'F' END AS sexe,
|
|
salarie.sal_matr AS matricule,
|
|
salarie.sal_matr AS code,
|
|
salarie.sal_matr 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,
|
|
sal_naiss AS nom_naissance,
|
|
coalesce(t_situations_famille.oid,0) AS situation_famille_id,
|
|
0 AS profil_id, -- dernier profil salarié.
|
|
max(h_cnt_trav.date_debut) AS date_debut, -- date de début du dernier contrat.
|
|
max(h_cnt_trav.date_fin) AS date_fin, -- date de fin du dernier contrat.
|
|
salarie.v_sal_dat_cemp AS date_entree_ets,
|
|
max(h_cnt_trav.date_fin) AS date_sortie_ets,
|
|
-- Champs dédiés au public.
|
|
'1900-01-01'::date AS date_entree_fp,
|
|
'1900-01-01'::date AS date_entree_fph,
|
|
0 AS no_adeli,
|
|
0 AS code_cotisation_id,
|
|
0 AS matricule_retraite
|
|
FROM prod_ccmx.v_salarie AS salarie
|
|
JOIN w_cnt AS h_cnt_trav ON 1=1
|
|
AND h_cnt_trav.ent_id = salarie.ent_id
|
|
AND h_cnt_trav.sal_matr = salarie.sal_matr
|
|
AND h_cnt_trav.cnt_id = salarie.cnt_id
|
|
LEFT JOIN rh.t_codes_postaux ON t_codes_postaux.code = salarie.sal_cp
|
|
LEFT JOIN rh.t_situations_famille ON t_situations_famille.code_original = salarie.fam_id
|
|
LEFT JOIN rh.t_entreprises ON t_entreprises.code_original = salarie.ent_id
|
|
LEFT JOIN rh.t_nationalites ON t_nationalites.code_original = salarie.sal_cod_pays
|
|
--LEFT JOIN w_profils ON w_profils.matricule = salaries.psa_salarie
|
|
WHERE salarie.eta_id = '0001'
|
|
GROUP BY 1,2,3,4,5,6,7,8,9,10,11,12,13,17,19,20,21,22,23
|
|
;
|
|
|
|
]]></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_cnt.date_debut,
|
|
w_cnt.date_fin,
|
|
w_cnt.numero_contrat,
|
|
w_cnt.numero_contrat AS code_original,
|
|
coalesce(t_etablissements.oid,0) AS etablissement_id,
|
|
(max(ARRAY[extract(EPOCH from w_profils.date_fin), w_profils.profil_id]))[2] AS profil_id -- Il se peut que pour un même contrat, il y est plusieurs profils. Dans ce cas on prend le profil le plus récent.
|
|
FROM w_cnt
|
|
JOIN rh.p_salaries ON p_salaries.matricule = sal_matr
|
|
JOIN rh.t_etablissements ON t_etablissements.code_original = '0001' -- @TODO faire quelque chose pour les contrats qui sont ratachés directement à l'entreprise...
|
|
JOIN w_profils ON 1=1
|
|
AND w_profils.matricule = sal_matr
|
|
AND w_profils.numero_contrat = w_cnt.numero_contrat
|
|
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.numero_contrat,
|
|
sum(t2.duree) AS anciennete_anterieure_jours,
|
|
sum(t2.duree) / 30 AS anciennete_anterieure_calculee_mois
|
|
FROM w_cnt AS t1
|
|
JOIN w_cnt AS t2 ON 1=1
|
|
AND t2.sal_matr = t1.sal_matr
|
|
AND t2.cnt_date < t1.cnt_date
|
|
group by 1
|
|
) AS subq
|
|
WHERE 1=1
|
|
AND p_contrats.numero_contrat = subq.numero_contrat
|
|
;
|
|
|
|
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,
|
|
p_calendrier_mois.mois AS mois,
|
|
GREATEST(p_calendrier_mois.date_debut, w_profils.date_debut) AS date_debut,
|
|
LEAST(p_calendrier_mois.date_fin, w_profils.date_fin) AS date_fin,
|
|
CASE WHEN p_salaries.date_entree_ets BETWEEN p_calendrier_mois.date_debut AND p_calendrier_mois.date_fin THEN 1 ELSE 0 END AS nombre_entrees,
|
|
CASE WHEN p_salaries.date_sortie_ets BETWEEN p_calendrier_mois.date_debut AND p_calendrier_mois.date_fin THEN 1 ELSE 0 END AS nombre_departs,
|
|
CASE WHEN p_contrats.date_debut BETWEEN p_calendrier_mois.date_debut AND p_calendrier_mois.date_fin THEN 1 ELSE 0 END AS nombre_debut_contrat,
|
|
CASE WHEN p_contrats.date_fin BETWEEN p_calendrier_mois.date_debut AND p_calendrier_mois.date_fin THEN 1 ELSE 0 END AS nombre_fin_contrat,
|
|
w_profils.est_hors_periode,
|
|
CASE WHEN p_calendrier_mois.date_debut BETWEEN p_contrats.date_debut AND p_contrats.date_fin THEN 1 ELSE 0 END AS present_debut_mois,
|
|
CASE WHEN p_calendrier_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(p_calendrier_mois.date_fin, w_profils.date_fin), COALESCE(p_salaries.date_naissance, '1962-04-18'::date), 'ny') AS age_id,
|
|
LEAST(p_calendrier_mois.date_fin, w_profils.date_fin)::date - COALESCE(p_salaries.date_naissance, '1962-04-18'::date) AS age_jours,
|
|
p_contrats.anciennete_anterieure_jours
|
|
+ (LEAST(p_calendrier_mois.date_fin, w_profils.date_fin) - p_contrats.date_debut)
|
|
+ 1
|
|
AS anciennete_jours,
|
|
base.cti_months_between(p_contrats.date_debut, p_calendrier_mois.date_fin)
|
|
+ p_contrats.anciennete_anterieure_calculee_mois
|
|
AS anciennete_mois,
|
|
floor(
|
|
(
|
|
base.cti_months_between(p_contrats.date_debut, p_calendrier_mois.date_fin)
|
|
+ p_contrats.anciennete_anterieure_calculee_mois
|
|
) / 12
|
|
) AS anciennete_annee_id
|
|
FROM w_profils
|
|
JOIN base.p_calendrier_mois ON base.cti_overlaps(w_profils.date_debut, w_profils.date_fin, p_calendrier_mois.date_debut, p_calendrier_mois.date_fin)
|
|
JOIN rh.p_contrats ON p_contrats.numero_contrat = w_profils.numero_contrat
|
|
JOIN rh.p_salaries ON p_salaries.matricule = w_profils.matricule
|
|
WHERE 1=1
|
|
AND p_calendrier_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
|
|
;
|
|
|
|
CREATE TEMP TABLE w_hp AS
|
|
SELECT
|
|
0 AS eta,
|
|
bulletin.sal_matr AS matricule,
|
|
-- Dates d'activité
|
|
date_debut,
|
|
date_fin,
|
|
to_char(date_fin, 'YYYYMM')::numeric AS mois_activite,
|
|
-- Dates de paie
|
|
date_paie,
|
|
substr(bulletin.bul_id, 1, 6)::numeric AS mois_paie,
|
|
pla_id AS rubrique,
|
|
reg_id AS compte,
|
|
--phb_organisme AS organisme,
|
|
sum(lig_bas1) AS base,
|
|
sum(CASE WHEN lig_typ <= 10 THEN lig_mont1 ELSE 0 END) AS brut,
|
|
sum(lig_taux1) AS tx_sal,
|
|
sum(CASE WHEN lig_typ = 50 THEN lig_mont1 ELSE 0 END) AS mt_sal,
|
|
sum(lig_taux2) AS tx_pat,
|
|
sum(CASE WHEN lig_typ = 50 THEN lig_mont2 * (-1) ELSE 0 END) AS mt_pat,
|
|
sum(CASE WHEN lig_typ <= 50 THEN lig_mont1 ELSE 0 END) AS net_imposable,
|
|
sum(CASE WHEN lig_typ <= 85 THEN lig_mont1 ELSE 0 END) AS net_a_payer,
|
|
sum(0) AS od_net
|
|
FROM prod_ccmx.v_bulletin AS bulletin
|
|
join prod_ccmx.ligne ON ligne.bul_id = bulletin.bul_id
|
|
WHERE 1=1
|
|
and bul_type = 'V' -- on ne conserve que les bulletins corrects.
|
|
and lig_ok ='O' -- on ne conserve que les lignes correctes.
|
|
and lig_typ NOT IN (15, 25, 55, 65, 80, 86, 99) -- Pas certaines rubriques de totaux
|
|
and pla_id NOT IN ('1000', '2805', '7980', '7981', '7982', '7983', '8961') -- Inhibition de la rubrique "2805 - Rep.compens.acquis"
|
|
and substr(lig_int, 1, 1) != '*'
|
|
-- Limitation d'historique => fixée dans l'aspirateur.
|
|
and bulletin.eta_id = '0001'
|
|
GROUP BY 1,2,3,4,5,6,7,8,9
|
|
;
|
|
|
|
-- #correction
|
|
UPDATE w_hp
|
|
SET date_paie = (mois_paie||'01')::date + '1 month - 1 day'::interval
|
|
WHERE to_char(date_paie, 'YYYYMM')::numeric != mois_paie
|
|
;
|
|
|
|
CREATE INDEX i_w_hp_1
|
|
ON w_hp
|
|
USING btree (matricule)
|
|
;
|
|
|
|
CREATE INDEX i_w_hp_2
|
|
ON w_hp
|
|
USING btree (mois_activite)
|
|
;
|
|
|
|
CREATE INDEX i_w_hp_3
|
|
ON w_hp
|
|
USING btree (mois_paie)
|
|
;
|
|
|
|
CREATE INDEX i_w_hp_4
|
|
ON w_hp
|
|
USING btree (rubrique)
|
|
;
|
|
|
|
-- Insertion dans la table de production CTI.
|
|
TRUNCATE rh.p_historique_paie
|
|
;
|
|
|
|
SELECT base.cti_stash_table_indexes('rh', 'p_historique_paie')
|
|
;
|
|
|
|
INSERT INTO rh.p_historique_paie
|
|
(
|
|
age_id,
|
|
base,
|
|
contrat_id,
|
|
contrat_mois_id,
|
|
date_debut,
|
|
date_fin,
|
|
date_paie,
|
|
mois_activite,
|
|
mois_paie,
|
|
montant_avantage_nature,
|
|
montant_brut,
|
|
montant_cotisation_patronale,
|
|
montant_cotisation_salarie,
|
|
montant_frais_imposables,
|
|
montant_net_a_payer_salarie,
|
|
montant_net_imposable_salarie,
|
|
montant_od_net_salarie,
|
|
organisme_cotisation_id,
|
|
rubrique_id,
|
|
salarie_id,
|
|
taux_cotisation_patronale,
|
|
taux_cotisation_salarie,
|
|
compte_id
|
|
)
|
|
SELECT
|
|
date_part('year', age(w_hp.date_debut, date_naissance)) AS age_id,
|
|
w_hp.base AS base,
|
|
(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.oid]))[2] AS contrat_mois_id,
|
|
w_hp.date_debut AS date_debut,
|
|
w_hp.date_fin AS date_fin,
|
|
w_hp.date_paie AS date_paie,
|
|
w_hp.mois_activite AS mois_activite,
|
|
w_hp.mois_paie AS mois_paie,
|
|
0 AS montant_avantage_nature,
|
|
w_hp.brut AS montant_brut,
|
|
w_hp.mt_pat AS montant_cotisation_patronale,
|
|
w_hp.mt_sal AS montant_cotisation_salarie,
|
|
0 AS montant_frais_imposables,
|
|
w_hp.net_a_payer AS montant_net_a_payer_salarie,
|
|
w_hp.net_imposable AS montant_net_imposable_salarie,
|
|
w_hp.od_net AS montant_od_net_salarie,
|
|
0 AS organisme_cotisation_id,
|
|
t_rubriques.oid AS rubrique_id,
|
|
p_salaries.oid AS salarie_id,
|
|
w_hp.tx_pat AS taux_cotisation_patronale,
|
|
w_hp.tx_sal AS taux_cotisation_salarie,
|
|
coalesce(t_compte.oid, 0) AS compte_id
|
|
FROM w_hp
|
|
JOIN rh.t_rubriques ON t_rubriques.code_original = w_hp.rubrique
|
|
JOIN rh.p_salaries ON p_salaries.matricule = w_hp.matricule
|
|
-- LEFT JOIN rh.t_organismes_cotisation ON t_organismes_cotisation.code_original = w_hp.organisme
|
|
LEFT JOIN rh.p_contrats_mois ON 1=1
|
|
AND p_contrats_mois.salarie_id = p_salaries.oid
|
|
--AND p_contrats_mois.mois_activite = w_hp.mois
|
|
AND base.cti_overlaps(p_contrats_mois.date_debut, p_contrats_mois.date_fin, w_hp.date_debut, w_hp.date_fin)
|
|
LEFT JOIN rh.t_compte ON t_compte.code_original = w_hp.compte
|
|
GROUP BY 1,2,5,6,7,8,9,10,11,12,13,14,15,16,17,18,19,20,21,22,23
|
|
;
|
|
|
|
SELECT base.cti_stash_pop_table_indexes('rh', 'p_historique_paie')
|
|
;
|
|
|
|
|
|
-- 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
|
|
-- Dates d'activité
|
|
date_debut,
|
|
date_fin,
|
|
to_char(date_fin, 'YYYYMM')::numeric AS mois_activite,
|
|
-- Dates de paie
|
|
date_paie,
|
|
substr(bulletin.bul_id, 1, 6)::numeric AS mois_paie,
|
|
bulletin.sal_matr AS matricule,
|
|
substr(bulletin.bul_id, 1, 4)::numeric AS mois,
|
|
sum(case when pla_id = 'BRUT' then lig_mont1 else 0 end)::numeric AS brut,
|
|
sum(case when pla_id = 'IMPO' then lig_mont1 else 0 end)::numeric AS net_imposable,
|
|
sum(case when pla_id = 'NETT' then lig_mont1 else 0 end)::numeric AS net_a_payer,
|
|
sum(case when pla_id = 'TOTR' then lig_mont1 else 0 end)::numeric AS mt_sal,
|
|
sum(case when pla_id = 'TOTR' then lig_mont2 * (-1) else 0 end)::numeric AS mt_pat
|
|
from prod_ccmx.v_bulletin AS bulletin
|
|
join prod_ccmx.ligne ON ligne.bul_id = bulletin.bul_id
|
|
where 1=1
|
|
AND pla_id IN ('BRUT', 'TOTR', 'IMPO', 'NETT')
|
|
and bul_type = 'V' -- on ne conserve que les bulletins corrects.
|
|
and bulletin.eta_id = '0001'
|
|
group by 1,2,3,4,5,6,7
|
|
;
|
|
|
|
-- #correction
|
|
UPDATE w_totaux
|
|
SET date_paie = (mois_paie||'01')::date + '1 month - 1 day'::interval
|
|
WHERE to_char(date_paie, 'YYYYMM')::numeric != mois_paie
|
|
;
|
|
|
|
-- Inserer 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
|
|
(
|
|
age_id,
|
|
contrat_id,
|
|
contrat_mois_id,
|
|
date_debut,
|
|
date_fin,
|
|
date_paie,
|
|
mois_activite,
|
|
mois_paie,
|
|
base,
|
|
montant_avantage_nature,
|
|
montant_brut,
|
|
montant_cotisation_patronale,
|
|
montant_cotisation_salarie,
|
|
montant_frais_imposables,
|
|
montant_net_a_payer_salarie,
|
|
montant_net_imposable_salarie,
|
|
montant_od_net_salarie,
|
|
organisme_cotisation_id,
|
|
profil_id, -- @deprecated
|
|
rubrique_id,
|
|
salarie_id,
|
|
taux_cotisation_patronale,
|
|
taux_cotisation_salarie
|
|
)
|
|
SELECT
|
|
age_id,
|
|
contrat_id,
|
|
contrat_mois_id,
|
|
subq.date_debut,
|
|
subq.date_fin,
|
|
subq.date_paie,
|
|
subq.mois_activite,
|
|
subq.mois_paie,
|
|
0 AS base,
|
|
0 AS montant_avantage_nature,
|
|
sum(brut - subq.montant_brut) AS montant_brut,
|
|
sum(mt_pat - subq.montant_cotisation_patronale) AS montant_cotisation_patronale,
|
|
sum(mt_sal - subq.montant_cotisation_salarie) AS montant_cotisation_salarie,
|
|
0 AS montant_frais_imposables,
|
|
sum(net_a_payer - subq.montant_net_a_payer_salarie) AS montant_net_a_payer_salarie,
|
|
sum(net_imposable - subq.montant_net_imposable_salarie) AS montant_net_imposable_salarie,
|
|
0 AS montant_od_net_salarie,
|
|
subq.organisme_cotisation_id AS organisme_cotisation_id,
|
|
subq.profil_id AS profil_id,
|
|
(SELECT oid FROM rh.t_rubriques WHERE code = 'C000') AS rubrique_id,
|
|
subq.salarie_id AS salarie_id,
|
|
0 AS taux_cotisation_patronale,
|
|
0 AS taux_cotisation_salarie
|
|
FROM
|
|
(
|
|
SELECT
|
|
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,
|
|
sum(montant_avantage_nature) AS montant_avantage_nature,
|
|
sum(montant_brut) AS montant_brut,
|
|
sum(montant_cotisation_patronale) AS montant_cotisation_patronale,
|
|
sum(montant_cotisation_salarie) AS montant_cotisation_salarie,
|
|
0 AS montant_frais_imposables,
|
|
sum(montant_net_a_payer_salarie) AS montant_net_a_payer_salarie,
|
|
sum(montant_net_imposable_salarie) AS montant_net_imposable_salarie,
|
|
0 AS montant_od_net_salarie,
|
|
0 AS organisme_cotisation_id,
|
|
0 AS profil_id, -- p_historique_paie.profil_id,
|
|
(SELECT oid FROM rh.t_rubriques WHERE code = 'C000'),
|
|
p_historique_paie.salarie_id,
|
|
0 AS taux_cotisation_patronale,
|
|
0 AS taux_cotisation_salarie
|
|
FROM rh.p_historique_paie
|
|
JOIN rh.p_salaries ON p_salaries.oid = p_historique_paie.salarie_id
|
|
GROUP BY 1,2,3,4,5,6,7,8,9, 18,19,20,21
|
|
) AS subq
|
|
JOIN rh.p_salaries ON p_salaries.oid = subq.salarie_id
|
|
JOIN w_totaux ON 1=1
|
|
AND w_totaux.matricule = p_salaries.matricule
|
|
AND w_totaux.date_debut = subq.date_debut
|
|
AND w_totaux.date_fin = subq.date_fin
|
|
GROUP BY 1,2,3,4,5,6,7,8,9, 18,19,20,21
|
|
HAVING 1!=1
|
|
OR sum(brut - subq.montant_brut) <> 0
|
|
OR sum(mt_pat - subq.montant_cotisation_patronale) <> 0
|
|
OR sum(mt_sal - subq.montant_cotisation_salarie) <> 0
|
|
OR sum(net_a_payer - subq.montant_net_a_payer_salarie) <> 0
|
|
OR sum(net_imposable - subq.montant_net_imposable_salarie) <> 0
|
|
;
|
|
|
|
/*
|
|
|
|
Quels sont les écarts cumulés > 0 ? :
|
|
|
|
SELECT
|
|
p_salaries.matricule,
|
|
p_historique_paie.*
|
|
FROM rh.p_historique_paie
|
|
JOIN rh.p_salaries on p_salaries.oid = p_historique_paie.salarie_id
|
|
JOIN rh.t_rubriques on t_rubriques.oid = p_historique_paie.rubrique_id
|
|
WHERE 1=1
|
|
AND t_rubriques.code_original = 'C000'
|
|
AND
|
|
(1!=1
|
|
OR p_historique_paie.base <> 0
|
|
OR p_historique_paie.montant_brut <> 0
|
|
OR p_historique_paie.montant_cotisation_salarie <> 0
|
|
OR p_historique_paie.montant_cotisation_patronale <> 0
|
|
OR p_historique_paie.montant_net_a_payer_salarie <> 0
|
|
OR p_historique_paie.montant_net_imposable_salarie <> 0
|
|
OR p_historique_paie.montant_avantage_nature <> 0
|
|
)
|
|
ORDER BY 1,4 DESC
|
|
;
|
|
|
|
*/
|
|
|
|
]]></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 rh.p_contrats ON p_contrats.oid = p_contrats_mois.contrat_id
|
|
join w_profils ON 1=1
|
|
AND base.cti_overlaps(w_profils.date_debut,w_profils.date_fin,p_contrats_mois.date_debut,p_contrats_mois.date_fin)
|
|
--AND w_profils.date_debut = p_contrats_mois.date_debut
|
|
--AND w_profils.date_fin = p_contrats_mois.date_fin
|
|
AND w_profils.numero_contrat = p_contrats.numero_contrat
|
|
group by 1,2,3,4,5
|
|
;
|
|
|
|
-- @TODO : Calcul ETP théorique, Il faudra sans doute optimiser (cf. Cegid)
|
|
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 -- N/R => Temps complet
|
|
WHEN substr(type_temps_travail_code, 1, 1) = 'C' THEN 100 -- Tous les codes C => Temps complet
|
|
WHEN substr(type_temps_travail_code, 1, 1) = 'I'
|
|
AND length(substr(type_temps_travail_code, 2)) = 0 THEN 50 -- Tous les codes I sans % défini => Temps partiel à 50%
|
|
WHEN length(substr(type_temps_travail_code, 2)) = 0 THEN 1 -- Pas de % défini => Temps minimum à 1%
|
|
ELSE substr(type_temps_travail_code, 2)::numeric -- Le reste (P) => % défini
|
|
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)
|
|
;
|
|
|
|
]]></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>
|