<?xml version="1.0" encoding="ISO-8859-15"?>
|
|
<ROOT>
|
|
<NODE name="INIT" label="INITIALISATIONS">
|
|
<NODE label="Pre-traitements des tables prestataire">
|
|
<sqlcmd><![CDATA[
|
|
|
|
-- Création d'une vue temporaire pour exploiter la concaténation d'A01_COMPTA issue de Pleiades CS et e5 (l'actuel).
|
|
-- MHA - On laisse le DROP VIEW le temps d'être sûr que la vue soit supprimée (à retirer 06-2024)
|
|
DROP VIEW IF EXISTS prod_pleiades2.v_a01_compta
|
|
;
|
|
|
|
CREATE TEMP TABLE w_a01_compta AS
|
|
SELECT
|
|
*,
|
|
sum(montant) over w as montant_total
|
|
FROM prod_pleiades2.a01_compta
|
|
window w as (partition by matricule, poste, periode_imputation, periode_origine, sous_periode)
|
|
;
|
|
|
|
ANALYZE w_a01_compta
|
|
;
|
|
|
|
-- Création de période pour les CSP.
|
|
drop table if exists w_cnt_csp
|
|
;
|
|
|
|
create temp table w_cnt_csp as
|
|
select
|
|
salarie.matricule as mat,
|
|
salarie.matricule||'-'||(rank() over w)::text as csp_num,
|
|
emploi.begin_date::date as date_debut,
|
|
coalesce(lead(emploi.begin_date::date) over w - 1, '20991231'::date) as date_fin,
|
|
ta_emploi.emploicode as emp_code_original,
|
|
ta_pcs.pcscode as csp_code_original,
|
|
xtp_mednonmed.code as statut_code_original
|
|
from prod_pleiades2.relationcontrat
|
|
join prod_pleiades2.salarie on salarie.oid = relationcontrat.relatmatricule
|
|
join prod_pleiades2.emploi on emploi.emploirelation = relationcontrat.oid
|
|
join prod_pleiades2.ta_emploi on ta_emploi.oid = emploi.emploi
|
|
join prod_pleiades2.ta_pcs on ta_pcs.oid = ta_emploi.emploipcs
|
|
join prod_pleiades2.xtp_mednonmed on xtp_mednonmed.oid = emploi.xtp_mednonmed
|
|
window w as (partition by salarie.oid order by emploi.begin_date)
|
|
;
|
|
|
|
-- Création de période pour les UFs.
|
|
drop table if exists w_cnt_ufs
|
|
;
|
|
|
|
create temp table w_cnt_ufs as
|
|
select
|
|
salarie.matricule as mat,
|
|
salarie.matricule||'-'||(rank() over w)::text as ufs_num,
|
|
xrcaffectuf.dteffet::date as date_debut,
|
|
coalesce(lead(xrcaffectuf.dteffet::date) over w - 1, '20991231'::date) as date_fin,
|
|
xrcaffectuf.ufpaie as cec_code_original,
|
|
xunitefct.code as uf_code_original -- UF de paie.
|
|
from prod_pleiades2.relationcontrat
|
|
join prod_pleiades2.salarie on salarie.oid = relationcontrat.relatmatricule
|
|
join prod_pleiades2.xrcaffectuf on xrcaffectuf.relationcontrat = relationcontrat.oid
|
|
join prod_pleiades2.xunitefct on xunitefct.oid = xrcaffectuf.xunitefct
|
|
where xrcaffectuf.ufprincipale = 1
|
|
window w as (partition by salarie.oid order by xrcaffectuf.dteffet)
|
|
;
|
|
|
|
-- Création de période pour les qualifications.
|
|
drop table if exists w_cnt_qua
|
|
;
|
|
|
|
create temp table w_cnt_qua as
|
|
select
|
|
salarie.matricule as mat,
|
|
salarie.matricule||'-'||(rank() over w)::text as qua_num,
|
|
qualification.begin_date::date as date_debut,
|
|
coalesce(lead(qualification.begin_date::date) over w - 1, '20991231'::date) as date_fin,
|
|
ta_qualif.qualifcode as qua_code_original
|
|
from prod_pleiades2.relationcontrat
|
|
join prod_pleiades2.salarie on salarie.oid = relationcontrat.relatmatricule
|
|
join prod_pleiades2.qualification on qualification.qualifrelation = relationcontrat.oid
|
|
join prod_pleiades2.ta_qualif on ta_qualif.oid = qualification.qualification
|
|
window w as (partition by salarie.oid order by qualification.begin_date)
|
|
;
|
|
|
|
-- Table des types de temps de travail.
|
|
drop table if exists w_cnt_ttt
|
|
;
|
|
|
|
create temp table w_cnt_ttt as
|
|
with toto as (
|
|
select
|
|
salarie.oid,
|
|
salarie.matricule,
|
|
horaire.begin_date,
|
|
(max(ARRAY[horaire.timestamp::numeric, horaire.horpourcttxpl]))[2] as horpourcttxpl
|
|
from prod_pleiades2.relationcontrat
|
|
join prod_pleiades2.salarie on salarie.oid = relationcontrat.relatmatricule
|
|
join prod_pleiades2.horaire on horaire.horcontr = relationcontrat.oid
|
|
-- where salarie.matricule = '90059' -- matricule en erreur (SC-7290).
|
|
group by 1,2,3
|
|
)
|
|
select
|
|
toto.matricule as mat,
|
|
toto.matricule||'-'||(rank() over w)::text as ttt_num,
|
|
toto.begin_date::date as date_debut,
|
|
coalesce(lead(toto.begin_date::date) over w - 1, '20991231'::date) as date_fin,
|
|
case when @toto.horpourcttxpl >= 100 then 'TC' else 'TP'||(@toto.horpourcttxpl)::text end as ttt_code_original,
|
|
@toto.horpourcttxpl / 100 as etp_cnt
|
|
from toto
|
|
window w as (partition by toto.oid order by toto.begin_date)
|
|
;
|
|
|
|
drop table if exists w_cnt_tho
|
|
;
|
|
|
|
create temp table w_cnt_tho as
|
|
select
|
|
salarie.matricule as mat,
|
|
salarie.matricule||'-'||(rank() over w)::text as tho_num,
|
|
xrcaffectcompl.begin_date::date as date_debut,
|
|
coalesce(lead(xrcaffectcompl.begin_date::date) over w - 1, '20991231'::date) as date_fin,
|
|
xta_jrnuitaltsr.code as tho_code_original
|
|
from prod_pleiades2.relationcontrat
|
|
join prod_pleiades2.salarie on salarie.oid = relationcontrat.relatmatricule
|
|
join prod_pleiades2.xrcaffectcompl on xrcaffectcompl.relationcontrat = relationcontrat.oid
|
|
join prod_pleiades2.xta_jrnuitaltsr on xta_jrnuitaltsr.oid = xrcaffectcompl.xta_jrnuitaltsr
|
|
window w as (partition by salarie.oid order by xrcaffectcompl.begin_date)
|
|
;
|
|
|
|
-- Création table des contrats.
|
|
-- Source intégrateur Pleiades : "Attention, sur E5, le passage de CDD à CDI n'est pas à l'origine d'un nouveau contrat contrairement à Pléiades CS".
|
|
-- On mélange donc les 2 historiques de contrat et de type de contrat pour n'en faire qu'une seul comme dans CS.
|
|
drop table if exists w_cnt
|
|
;
|
|
|
|
create temp table w_cnt as
|
|
with toto as (
|
|
select
|
|
salarie.matricule as mat,
|
|
salarie.matricule||'-'||row_number() over w as cnt, -- relationcontrat.relatnum
|
|
relationcontrat.relatnum,
|
|
typejuridqctr.begin_date::date as date_debut, -- relationcontrat.relatdatedeb
|
|
coalesce(nullif(typejuridqctr.end_date::date, '29990101'::date), relationcontrat.relatdatefin::date, '20991231'::date) as date_fin, -- relationcontrat.relatdatefin
|
|
nullif(ta_relamotifdeb.relatcodedeb, '') as motif_debut,
|
|
coalesce(case when lead(contrat.ctrrelation) over w = contrat.ctrrelation then 'CTI-TO_CDI' else null end, nullif(ta_relamotiffin.relationcodefin, '')) as motif_fin,
|
|
ta_relamotiffin.relationcodefin,
|
|
ta_contrattype.contrattypecode as type_contrat,
|
|
contrat.ctrsociete as etablissement,
|
|
coalesce(xunitefct.code, chr(1)||'*') as uf_localisation,
|
|
null::text as mat_remp
|
|
from prod_pleiades2.contrat
|
|
join prod_pleiades2.relationcontrat on relationcontrat.oid = contrat.ctrrelation
|
|
join prod_pleiades2.salarie on salarie.oid = relationcontrat.relatmatricule
|
|
join prod_pleiades2.ta_relamotifdeb on ta_relamotifdeb.oid = relationcontrat.relatmotifdeb
|
|
left join prod_pleiades2.ta_relamotiffin on ta_relamotiffin.oid = relationcontrat.relatmotiffin
|
|
join prod_pleiades2.typejuridqctr on contrat.oid = typejuridqctr.typecontrat
|
|
join prod_pleiades2.ta_contrattype on ta_contrattype.oid = typejuridqctr.typejuridique
|
|
left join prod_pleiades2.xrccomplement on xrccomplement.relationcontrat = relationcontrat.oid
|
|
left join prod_pleiades2.xunitefct on xunitefct.oid = xrccomplement.uflocalisation
|
|
window w as (partition by relationcontrat.relatmatricule order by typejuridqctr.begin_date))
|
|
,tata as (
|
|
select
|
|
*,
|
|
date_fin - date_debut + 1 as duree,
|
|
coalesce((lag(date_fin) over w) + 1 = date_debut, false) as continue,
|
|
coalesce((lead(date_debut) over w) - 1 = date_fin, false) as continue2
|
|
from toto
|
|
window w as (partition by mat order by date_debut))
|
|
,titi as (
|
|
select
|
|
*,
|
|
case when lag(continue2) over w then false else continue2 end as new_cluster,
|
|
case when continue then lag(duree) over w else 0 end as prec_duree
|
|
from tata
|
|
window w as (partition by mat order by mat, date_debut))
|
|
,tutu as (
|
|
select * ,
|
|
case when new_cluster then count(new_cluster) over w else null end as cluster_id
|
|
from titi
|
|
window w as (partition by mat order by date_debut))
|
|
,tyty as (
|
|
select
|
|
*,
|
|
max(cluster_id) over wb as cl2
|
|
from tutu
|
|
window wb as (PARTITION BY mat ORDER BY date_debut rows unbounded preceding))
|
|
select
|
|
mat,
|
|
cnt,
|
|
relatnum,
|
|
date_debut,
|
|
date_fin,
|
|
motif_debut,
|
|
motif_fin,
|
|
relationcodefin,
|
|
type_contrat,
|
|
etablissement,
|
|
uf_localisation,
|
|
mat_remp,
|
|
case when continue then sum(prec_duree) over w else 0 end as anciennete_anterieure_jours,
|
|
case when continue then sum(prec_duree) over w else 0 end / 30.0 as anciennete_anterieure_calculee_mois
|
|
from tyty
|
|
window w as (partition by mat, cl2 order by date_debut)
|
|
;
|
|
|
|
CREATE INDEX i_cnt_0 ON w_cnt USING btree(mat)
|
|
;
|
|
CREATE INDEX i_cnt_1 ON w_cnt USING btree(cnt)
|
|
;
|
|
|
|
-- Création table de compte comptables CS.
|
|
drop table if exists w_cs_compte
|
|
;
|
|
|
|
create temp table w_cs_compte as
|
|
select
|
|
a01_compta.poste as poste,
|
|
matricule,
|
|
compte,
|
|
('20'||periode_imputation)::numeric as periode_imputation,
|
|
sous_periode,
|
|
periode_origine,
|
|
montant,
|
|
montant_total
|
|
from w_a01_compta as a01_compta
|
|
where 1=1
|
|
and ecriture = 'C'
|
|
and compte != '999999999'
|
|
group by 1,2,3,4,5,6,7,8
|
|
;
|
|
|
|
-- Création table de compte comptables e5.
|
|
drop table if exists w_compte
|
|
;
|
|
|
|
create temp table w_compte as
|
|
with compte_9955 as (
|
|
select
|
|
'9955'::text as poste,
|
|
poste_paie.code as rub,
|
|
to_char(begin_date, 'YYYYMM')::int as date_debut,
|
|
to_char(coalesce(nullif(end_date::date, '29990101'::date), '2099-12-31'::date), 'YYYYMM')::int as date_fin
|
|
from prod_pleiades2.assiettetdp
|
|
join prod_pleiades2.ass on ass.oid = assiettetdp.assiette
|
|
join prod_pleiades2.cumulassiette on cumulassiette.oid = assiettetdp.codecumul
|
|
join prod_pleiades2.poste_paie on poste_paie.oid = assiettetdp.postepaie
|
|
where true
|
|
and ass.code = '235')
|
|
,compte_9956 as (
|
|
select
|
|
'9956'::text as poste,
|
|
poste_paie.code as rub,
|
|
to_char(begin_date, 'YYYYMM')::int as date_debut,
|
|
to_char(coalesce(nullif(end_date::date, '29990101'::date), '2099-12-31'::date), 'YYYYMM')::int as date_fin
|
|
from prod_pleiades2.assiettetdp
|
|
join prod_pleiades2.ass on ass.oid = assiettetdp.assiette
|
|
join prod_pleiades2.cumulassiette on cumulassiette.oid = assiettetdp.codecumul
|
|
join prod_pleiades2.poste_paie on poste_paie.oid = assiettetdp.postepaie
|
|
where true
|
|
and ass.code = '236'
|
|
and cumulassiette.code != '0')
|
|
select
|
|
coalesce(compte_9955.rub, compte_9956.rub, a01_compta.poste) as poste,
|
|
matricule,
|
|
compte,
|
|
('20'||periode_imputation)::numeric as periode_imputation,
|
|
sous_periode,
|
|
periode_origine,
|
|
montant,
|
|
montant_total
|
|
from w_a01_compta as a01_compta
|
|
left join compte_9955 on 1=1
|
|
and compte_9955.poste = a01_compta.regroupement
|
|
and ('20'||periode_imputation)::numeric between compte_9955.date_debut and compte_9955.date_fin
|
|
left join compte_9956 on 1=1
|
|
and compte_9956.poste = a01_compta.poste
|
|
and ('20'||periode_imputation)::numeric between compte_9956.date_debut and compte_9956.date_fin
|
|
where 1=1
|
|
and ecriture = 'C'
|
|
and compte != '999999999'
|
|
group by 1,2,3,4,5,6,7,8
|
|
;
|
|
|
|
-- Création d'une table brut de paie
|
|
|
|
-- Suppression de l'ancienne vue w_hp du schéma public.
|
|
DROP VIEW IF EXISTS public.w_hp
|
|
;
|
|
|
|
DROP TABLE IF EXISTS w_hp
|
|
;
|
|
CREATE TEMP TABLE w_hp AS
|
|
SELECT
|
|
paie_poste.ctid as hp_ctid,
|
|
salarie.matricule as mat,
|
|
relationcontrat.relatnum,
|
|
paie_periode.imputation::numeric as mois,
|
|
paie_periode.datevirement as date_virement,
|
|
rpad(paie_periode.moispaie, 6)||rpad(paie_periode.traitement, 1)||rpad(paie_periode.sousperiode, 2) as sous_periode,
|
|
paie_periode.datedebut as date_debut,
|
|
paie_periode.datefin as date_fin,
|
|
rpad(poste_paie.code, 4) as rub,
|
|
paie_poste.nombre as base,
|
|
sum(paie_poste.nombre) over w as base_total,
|
|
sum(paie_poste.nombre) over wi as base_total_imputation,
|
|
paie_poste.taux as tx,
|
|
paie_poste.montant as mt,
|
|
sum(paie_poste.montant) over w as montant_total,
|
|
sum(paie_poste.montant) over wi as montant_total_imputation
|
|
FROM prod_pleiades2.paie_poste
|
|
join prod_pleiades2.paie_periode on paie_periode.oid = paie_poste.paieperiode
|
|
join prod_pleiades2.poste_paie on poste_paie.oid = paie_poste.postepaie
|
|
join prod_pleiades2.relationcontrat on relationcontrat.oid = paie_periode.relationcontrat
|
|
join prod_pleiades2.salarie on salarie.oid = relationcontrat.relatmatricule
|
|
where to_char(paie_periode.datevirement, 'YYYYMM') >= CONCAT(SPLIT_PART(rhp('rhprovider_start'), '-', 1), SPLIT_PART(rhp('rhprovider_start'), '-', 2))
|
|
window w as (partition by salarie.matricule, relationcontrat.relatnum, poste_paie.code, paie_periode.imputation, to_char(paie_periode.datedebut, 'YYYYMM')),
|
|
wi as (partition by salarie.matricule, relationcontrat.relatnum, poste_paie.code, paie_periode.imputation)
|
|
;
|
|
|
|
CREATE INDEX i_hp_0 ON w_hp USING btree(mat)
|
|
;
|
|
CREATE INDEX i_hp_1 ON w_hp USING btree(rub)
|
|
;
|
|
CREATE INDEX i_hp_3 ON w_hp USING btree(hp_ctid)
|
|
;
|
|
|
|
-- Créer une table des bulletins.
|
|
-- Les rubriques de régulation (en "R") seront affectées systématiquement au 1er bulletin du mois.
|
|
DROP TABLE IF EXISTS w_bul
|
|
;
|
|
CREATE TEMP TABLE w_bul AS
|
|
with bul_mois as (
|
|
select
|
|
mat,
|
|
mois,
|
|
case when mois = to_char(date_debut, 'YYYYMM')::numeric then date_debut else (mois||'01')::date end as date_debut,
|
|
case when mois = to_char(date_debut, 'YYYYMM')::numeric then date_fin else base.cti_last_day((mois||'01')::date) end as date_fin,
|
|
count(*) over (partition by mat, mois) as nb_bul_month,
|
|
count(case when mois = to_char(date_debut, 'YYYYMM')::numeric then date_debut else null end) as nb_lines_month
|
|
from w_hp
|
|
group by 1,2,3,4)
|
|
--
|
|
select
|
|
mat||mois||lpad(rank() over (partition by mat, mois order by date_debut), 2, '0') as bul,
|
|
*
|
|
from bul_mois
|
|
where case when nb_lines_month = 0 then nb_bul_month = 1 else true end -- on ne conserve que les bulletins mois qui n'ont aucune ligne sur le mois d'imputation (100% de régul).
|
|
;
|
|
|
|
]]></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_original, code, texte, texte_court)
|
|
SELECT
|
|
oid,
|
|
societecode,
|
|
societenom,
|
|
substr(societenomc, 1, 50)
|
|
FROM prod_pleiades2.societe
|
|
WHERE 1=1
|
|
AND socsiren IN (SELECT rhp('siren'))
|
|
AND oid NOT IN (SELECT code_original FROM rh.t_entreprises)
|
|
;
|
|
|
|
-- Màj des Etablissements
|
|
INSERT INTO rh.t_etablissements(code_original, code, texte, texte_court, entreprise_id)
|
|
SELECT
|
|
societe.oid,
|
|
socsiren||socnic,
|
|
libelle,
|
|
substr(libelle, 1, 50),
|
|
t_entreprises.oid
|
|
FROM prod_pleiades2.societe
|
|
JOIN rh.t_entreprises ON t_entreprises.code_original = societe.oid
|
|
WHERE 1=1
|
|
AND socsiren IN (SELECT rhp('siren'))
|
|
AND societe.oid NOT IN (SELECT code_original FROM rh.t_etablissements)
|
|
;
|
|
|
|
-- Màj des catégories socio-professionnelles : à renseigner avec les données de prod.
|
|
INSERT INTO rh.t_categories_socio_professionnelle (code_original, code, texte, texte_court)
|
|
select pcscode, pcscode, max(pcslibelle1), max(substr(pcslibelle1, 1, 50))
|
|
from prod_pleiades2.ta_pcs
|
|
where pcscode NOT IN (SELECT code_original FROM rh.t_categories_socio_professionnelle)
|
|
GROUP BY 1,2
|
|
;
|
|
|
|
-- Màj des motifs de début de contrat.
|
|
INSERT INTO rh.t_motifs_debut_contrat(code_original, code, texte, texte_court)
|
|
select relatcodedeb, relatcodedeb, max(relatlibdeb), max(substr(relatlibcdeb, 1, 50))
|
|
from prod_pleiades2.ta_relamotifdeb
|
|
where relatcodedeb NOT IN (SELECT code_original FROM rh.t_motifs_debut_contrat)
|
|
GROUP BY 1,2
|
|
;
|
|
|
|
-- Màj des motifs de fin de contrat.
|
|
INSERT INTO rh.t_motifs_fin_contrat(code_original, code, texte, texte_court)
|
|
select relationcodefin, relationcodefin, max(relationlibfin), max(substr(relationlibcfin, 1, 50))
|
|
from prod_pleiades2.ta_relamotiffin
|
|
where relationcodefin NOT IN (SELECT code_original FROM rh.t_motifs_fin_contrat)
|
|
GROUP BY 1,2
|
|
;
|
|
|
|
-- Création d'un motif fictif "Passage en CDI".
|
|
INSERT INTO rh.t_motifs_fin_contrat(code_original, code, texte, texte_court)
|
|
select 'CTI-TO_CDI', 'CTI-TO_CDI', 'Passage en CDI', 'Passage en CDI'
|
|
where 'CTI-TO_CDI' NOT IN (SELECT code_original FROM rh.t_motifs_fin_contrat)
|
|
;
|
|
|
|
-- Màj des nationalités.
|
|
INSERT INTO rh.t_nationalites(code_original, code, texte, texte_court)
|
|
select code, code, max(lib_court), max(substr(lib_court, 1, 50))
|
|
from prod_pleiades2.nationalite
|
|
where code NOT IN (SELECT code_original FROM rh.t_nationalites)
|
|
GROUP BY 1,2
|
|
;
|
|
|
|
-- Màj des qualifications.
|
|
INSERT INTO rh.t_qualifications(code_original, code, texte, texte_court)
|
|
select trim(qualifcode), trim(qualifcode), max(trim(qualiflibelle)), max(trim(substr(qualiflib, 1, 50)))
|
|
from prod_pleiades2.ta_qualif
|
|
where trim(qualifcode) NOT IN (SELECT code_original FROM rh.t_qualifications)
|
|
GROUP BY 1,2
|
|
;
|
|
|
|
-- Màj des rubriques table rubrique
|
|
INSERT INTO rh.t_rubriques(code_original, code, texte, texte_court, rang_edition)
|
|
SELECT code, code, min(libapparaissant), substr(min(libapparaissant), 1, 50), code::int
|
|
FROM prod_pleiades2.poste_paie
|
|
WHERE code NOT IN (SELECT code_original FROM rh.t_rubriques)
|
|
GROUP BY 1,2,5
|
|
;
|
|
|
|
-- Màj des libellés des rubriques (IC-5439).
|
|
WITH rubs as (
|
|
SELECT
|
|
code,
|
|
min(libapparaissant) as texte,
|
|
substr(min(libapparaissant), 1, 50) as texte_court
|
|
FROM prod_pleiades2.poste_paie
|
|
GROUP BY 1
|
|
)
|
|
UPDATE rh.t_rubriques SET
|
|
texte = rubs.texte,
|
|
texte_court = rubs.texte_court
|
|
FROM rubs
|
|
WHERE 1=1
|
|
AND t_rubriques.code_original = rubs.code
|
|
AND t_rubriques.texte IS DISTINCT FROM rubs.texte
|
|
;
|
|
|
|
-- 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 comptes.
|
|
INSERT INTO rh.t_compte(code_original, code, texte, texte_court)
|
|
SELECT compte, compte, compte, compte
|
|
FROM w_compte
|
|
WHERE compte NOT IN (SELECT code_original FROM rh.t_compte WHERE code_original IS NOT NULL)
|
|
GROUP BY 1
|
|
;
|
|
|
|
-- Màj des situations de famille.
|
|
INSERT INTO rh.t_situations_famille(code_original, code, texte, texte_court)
|
|
select matrimonialcode, matrimonialcode, max(matrimoniallibl), max(substr(matrimoniallibl, 1, 50))
|
|
from prod_pleiades2.ta_matrimonial
|
|
where matrimonialcode NOT IN (SELECT code_original FROM rh.t_situations_famille)
|
|
GROUP BY 1,2
|
|
;
|
|
|
|
-- Màj des types de contrat.
|
|
INSERT INTO rh.t_types_contrat(code_original, code, texte, texte_court)
|
|
select contrattypecode, contrattypecode, max(contrattypelib), max(substr(contrattypelib, 1, 50))
|
|
from prod_pleiades2.ta_contrattype
|
|
where contrattypecode NOT IN (SELECT code_original FROM rh.t_types_contrat)
|
|
GROUP BY 1,2
|
|
;
|
|
|
|
-- Màj des statuts
|
|
INSERT INTO rh.t_statuts(code_original, code, texte, texte_court)
|
|
select code, code, max(libelle), max(substr(libelle, 1, 50))
|
|
from prod_pleiades2.xtp_mednonmed
|
|
where code NOT IN (SELECT code_original FROM rh.t_statuts)
|
|
GROUP BY 1,2
|
|
;
|
|
|
|
-- Màj des types de temps de travail
|
|
-- Penser à configurer les sections de classe avec TC et TP*.
|
|
INSERT INTO rh.t_types_temps_travail(code_original, code, texte, texte_court)
|
|
select
|
|
ttt_code_original,
|
|
ttt_code_original,
|
|
case when ttt_code_original = 'TC' then 'Temps Complet' else 'Temps Partiel '||substr(ttt_code_original, 3)||'%' end,
|
|
case when ttt_code_original = 'TC' then 'Temps Complet' else 'Temps Partiel '||substr(ttt_code_original, 3)||'%' end
|
|
from w_cnt_ttt
|
|
WHERE ttt_code_original NOT IN (SELECT code_original FROM rh.t_types_temps_travail)
|
|
group by 1,2,3,4
|
|
;
|
|
|
|
-- Màj des services
|
|
INSERT INTO rh.t_services(code_original, code, texte, texte_court)
|
|
select code, code, max(liblong), max(substr(libcourt, 1, 50))
|
|
from prod_pleiades2.xunitefct
|
|
where code NOT IN (SELECT code_original FROM rh.t_services)
|
|
GROUP BY 1,2
|
|
;
|
|
|
|
-- Màj des spécialités
|
|
INSERT INTO rh.t_specialites(code_original, code, texte, texte_court)
|
|
select code, code, max(liblong), max(substr(libcourt, 1, 50))
|
|
from prod_pleiades2.xta_saeq
|
|
where code NOT IN (SELECT code_original FROM rh.t_specialites)
|
|
GROUP BY 1,2
|
|
;
|
|
|
|
-- Màj des codes emploi
|
|
INSERT INTO rh.t_codes_emploi(code_original, code, texte, texte_court)
|
|
select emploicode, emploicode, max(emploilibelle), max(substr(emploilib, 1, 50))
|
|
from prod_pleiades2.ta_emploi
|
|
where emploicode NOT IN (SELECT code_original FROM rh.t_codes_emploi)
|
|
GROUP BY 1,2
|
|
;
|
|
|
|
-- Màj des types d'horaire.
|
|
INSERT INTO rh.t_types_horaire(code_original, code, texte, texte_court)
|
|
select code, code, max(liblong), max(substr(liblong, 1, 50))
|
|
from prod_pleiades2.xta_jrnuitaltsr
|
|
where code NOT IN (SELECT code_original FROM rh.t_types_horaire)
|
|
GROUP BY 1,2
|
|
;
|
|
|
|
-- Màj des codes emplois compta.
|
|
INSERT INTO rh.t_sections_analytiques(code_original, code, texte, texte_court)
|
|
select
|
|
anacode,
|
|
anacode,
|
|
analibelle,
|
|
substr(analibelle, 1, 50)
|
|
from prod_pleiades2.analytique
|
|
where anacode NOT IN (SELECT code_original FROM rh.t_sections_analytiques)
|
|
group by 1,2,3,4
|
|
;
|
|
|
|
-- Màj des UF de localisation
|
|
INSERT INTO rh.t_sections_analytiques_paie(code_original, code, texte, texte_court)
|
|
select code, code, max(liblong), max(substr(libcourt, 1, 50))
|
|
from prod_pleiades2.xunitefct
|
|
where code NOT IN (SELECT code_original FROM rh.t_sections_analytiques_paie)
|
|
GROUP BY 1,2
|
|
;
|
|
|
|
-- Màj des motifs d'arret
|
|
INSERT INTO rh.t_motifs_arret(code_original, code, texte, texte_court)
|
|
select motif, motif, liblong, substr(libcourt, 1, 50)
|
|
from prod_pleiades2.ta_motifevt
|
|
where motif NOT IN (SELECT code_original FROM rh.t_motifs_arret)
|
|
GROUP BY 1,2,3,4
|
|
;
|
|
|
|
-- @todo Màj des motifs de visite médicale
|
|
/*INSERT INTO rh.t_motifs_visite(code_original, code, texte, texte_court)
|
|
select ce, ce, max(c01), max(substr(c02, 1, 50))
|
|
from prod_pleiades2.d01v3_tabdef
|
|
where 1=1
|
|
and cb = 'MEDICA'
|
|
and ce NOT IN (SELECT code_original FROM rh.t_motifs_visite)
|
|
GROUP BY 1,2
|
|
;*/
|
|
|
|
-- Insertion du Plan Analytique.
|
|
TRUNCATE rh.t_plan_analytique
|
|
;
|
|
INSERT INTO rh.t_plan_analytique(oid, code, texte)
|
|
VALUES
|
|
(1, 'A01_COMPTA', 'Plan analytique a01_compta.')
|
|
;
|
|
|
|
-- Màj des sections analytiques.
|
|
INSERT INTO rh.t_section_analytique(code_original, code, texte, texte_court)
|
|
select imputation, imputation, imputation, imputation
|
|
from w_a01_compta
|
|
where imputation NOT IN (SELECT code FROM rh.t_section_analytique)
|
|
and imputation <> ''
|
|
group by 1,2,3,4
|
|
;
|
|
|
|
]]></sqlcmd>
|
|
</NODE>
|
|
</NODE>
|
|
<NODE name="PROD" label="RECUPERATION DES DONNEES DE PRODUCTION">
|
|
<NODE label="Chiffrier">
|
|
<sqlcmd><![CDATA[
|
|
|
|
DROP TABLE IF EXISTS w_chiffrier
|
|
;
|
|
CREATE TEMP TABLE w_chiffrier AS
|
|
SELECT
|
|
0 as entreprise_id,
|
|
0 as etablissement_id,
|
|
w_bul.mois,
|
|
w_bul.date_fin as date_paie,
|
|
w_bul.date_debut,
|
|
w_bul.date_fin,
|
|
w_bul.mat,
|
|
w_bul.bul,
|
|
sum(CASE WHEN rub = '6001' THEN mt ELSE 0 END) AS montant_brut,
|
|
sum(CASE WHEN rub = '8792' THEN mt ELSE 0 END) AS montant_cotisation_salarie,
|
|
sum(CASE WHEN rub = '8790' THEN mt ELSE 0 END) AS montant_cotisation_patronale, -- correction 6829 à intégrer (entre autres); 1er janvier 2016 : l'assiette est rentrée dans l'ordre.
|
|
sum(CASE WHEN rub = '8805' THEN mt ELSE 0 END) AS montant_net_imposable_salarie,
|
|
sum(CASE WHEN rub = '9700' THEN mt ELSE 0 END) AS montant_net_a_payer_salarie,
|
|
sum(CASE WHEN rub = '6019' THEN mt ELSE 0 END) AS nombre_heures_p,
|
|
sum(CASE WHEN rub = '9953' THEN mt ELSE 0 END) AS nombre_heures_w -- ou 6020 ?
|
|
FROM w_hp
|
|
JOIN w_bul on w_bul.bul = w_hp.mat||w_hp.mois||(case when to_char(w_hp.date_debut, 'YYYYMM')::numeric = w_hp.mois then substring(sous_periode, 8, 2) else '01' end)
|
|
WHERE true
|
|
and rub != '0457'
|
|
and rub in ('0600','0610','4000','4682','6001','8792','8790','8805','9700','6019','9953','8898','9688')
|
|
GROUP BY 1,2,3,4,5,6,7,8
|
|
HAVING false
|
|
OR sum(CASE WHEN rub = '0600' THEN mt ELSE 0 END) != 0
|
|
OR sum(CASE WHEN rub = '0610' THEN mt ELSE 0 END) != 0
|
|
OR sum(CASE WHEN rub = '4000' THEN mt ELSE 0 END) != 0
|
|
OR sum(CASE WHEN rub = '4682' THEN mt ELSE 0 END) != 0
|
|
OR sum(CASE WHEN rub = '6001' THEN mt ELSE 0 END) != 0
|
|
OR sum(CASE WHEN rub = '8792' THEN mt ELSE 0 END) != 0
|
|
OR sum(CASE WHEN rub = '8790' THEN mt ELSE 0 END) != 0
|
|
OR sum(CASE WHEN rub = '8805' THEN mt ELSE 0 END) != 0
|
|
OR sum(CASE WHEN rub = '9700' THEN mt ELSE 0 END) != 0
|
|
OR sum(CASE WHEN rub = '6019' THEN mt ELSE 0 END) != 0
|
|
OR sum(CASE WHEN rub = '9953' THEN mt ELSE 0 END) != 0
|
|
OR sum(CASE WHEN rub = '8898' THEN mt ELSE 0 END) != 0
|
|
OR sum(CASE WHEN rub = '9688' THEN mt ELSE 0 END) != 0
|
|
;
|
|
|
|
TRUNCATE rh.p_chiffrier_production
|
|
;
|
|
|
|
INSERT INTO rh.p_chiffrier_production (entreprise_id, etablissement_id, mois, nombre_salaries, montant_brut, nombre_heures)
|
|
SELECT
|
|
entreprise_id,
|
|
etablissement_id,
|
|
mois,
|
|
count(DISTINCT mat),
|
|
sum(montant_brut),
|
|
sum(nombre_heures_p)
|
|
FROM w_chiffrier
|
|
GROUP BY 1,2,3
|
|
;
|
|
|
|
]]></sqlcmd>
|
|
</NODE>
|
|
<NODE label="Pré-traitements">
|
|
<sqlcmd><![CDATA[
|
|
|
|
-- Détermination des limites d'évènements salariés (utilisé uniquement pour la ventilation jusqu'à aujourd'hui).
|
|
DROP TABLE IF EXISTS w_lmt
|
|
;
|
|
|
|
CREATE TEMP TABLE w_lmt AS
|
|
WITH w_lmt_cnt AS (
|
|
SELECT
|
|
mat,
|
|
min(date_debut) as date_debut,
|
|
max(date_fin) as date_fin
|
|
FROM w_cnt
|
|
GROUP BY 1),
|
|
w_lmt_bul as (
|
|
select
|
|
mat,
|
|
min(date_debut) as date_debut,
|
|
max(date_fin) as date_fin
|
|
from w_bul
|
|
group by 1)
|
|
SELECT
|
|
coalesce(salarie.matricule, w_lmt_cnt.mat, w_lmt_bul.mat) as mat,
|
|
min(least(w_lmt_cnt.date_debut, w_lmt_bul.date_debut)) as min_date,
|
|
greatest(least(max(w_lmt_cnt.date_fin), current_date), max(w_lmt_bul.date_fin)) as max_date
|
|
FROM prod_pleiades2.salarie
|
|
left JOIN w_lmt_cnt ON w_lmt_cnt.mat = salarie.matricule
|
|
left join w_lmt_bul on w_lmt_bul.mat = salarie.matricule
|
|
group by 1
|
|
;
|
|
|
|
-- Table des évènements salarié.
|
|
DROP TABLE IF EXISTS w_evt
|
|
;
|
|
|
|
CREATE TEMP TABLE w_evt AS
|
|
select
|
|
w_lmt.mat,
|
|
min(cal.date) as date_debut,
|
|
max(cal.date) as date_fin,
|
|
cal.mois,
|
|
w_cnt.cnt,
|
|
w_cnt.date_debut as cnt_date_debut,
|
|
w_cnt.date_fin as cnt_date_fin,
|
|
w_cnt_csp.csp_num,
|
|
w_cnt_ufs.ufs_num,
|
|
w_cnt_qua.qua_num,
|
|
w_cnt_ttt.ttt_num,
|
|
w_cnt_tho.tho_num,
|
|
-- w_cnt_spe.spe_code,
|
|
w_bul.bul,
|
|
w_bul.date_debut as bul_date_debut,
|
|
w_bul.date_fin as bul_date_fin,
|
|
case when w_cnt is NULL then 1 else 0 end as est_hors_periode
|
|
from base.p_calendrier as cal
|
|
JOIN w_lmt on cal.date BETWEEN min_date and max_date
|
|
left join w_cnt on 1=1
|
|
and w_cnt.mat = w_lmt.mat
|
|
and cal.date BETWEEN w_cnt.date_debut and w_cnt.date_fin
|
|
left join w_cnt_csp on 1=1
|
|
and w_cnt_csp.mat = w_lmt.mat
|
|
and cal.date BETWEEN w_cnt_csp.date_debut and w_cnt_csp.date_fin
|
|
left join w_cnt_ufs on 1=1
|
|
and w_cnt_ufs.mat = w_lmt.mat
|
|
and cal.date BETWEEN w_cnt_ufs.date_debut and w_cnt_ufs.date_fin
|
|
left join w_cnt_qua on 1=1
|
|
and w_cnt_qua.mat = w_lmt.mat
|
|
and cal.date BETWEEN w_cnt_qua.date_debut and w_cnt_qua.date_fin
|
|
left join w_cnt_ttt on 1=1
|
|
and w_cnt_ttt.mat = w_lmt.mat
|
|
and cal.date BETWEEN w_cnt_ttt.date_debut and w_cnt_ttt.date_fin
|
|
left join w_cnt_tho on 1=1
|
|
and w_cnt_tho.mat = w_lmt.mat
|
|
and cal.date BETWEEN w_cnt_tho.date_debut and w_cnt_tho.date_fin
|
|
-- left join w_cnt_spe on w_cnt_spe.mat = w_lmt.mat -- relation 1 pour 1.
|
|
left join w_bul on 1=1
|
|
and w_bul.mat = w_lmt.mat
|
|
and cal.date BETWEEN w_bul.date_debut and w_bul.date_fin
|
|
WHERE 1=1
|
|
AND cal.date >= rhp('rhprovider_start')::date
|
|
AND (1!=1
|
|
OR w_cnt.mat is not NULL
|
|
OR w_cnt_csp is not null
|
|
OR w_cnt_ufs is not null
|
|
OR w_cnt_qua is not null
|
|
OR w_cnt_ttt is not null
|
|
-- OR w_cnt_ttt is not null
|
|
OR w_bul.mat is not null)
|
|
group by 1,4,5,6,7,8,9,10,11,12,13,14,15,16--,17
|
|
;
|
|
|
|
]]></sqlcmd>
|
|
</NODE>
|
|
<NODE label="Profils">
|
|
<sqlcmd><![CDATA[
|
|
|
|
|
|
|
|
DROP TABLE IF EXISTS w_sal_oid
|
|
;
|
|
|
|
CREATE TEMP TABLE w_sal_oid AS
|
|
SELECT
|
|
oid as sal_oid,
|
|
matricule as sal_mat
|
|
FROM prod_pleiades2.salarie
|
|
GROUP BY 1,2
|
|
;
|
|
|
|
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 prestataire.
|
|
w_evt.mat,
|
|
w_evt.cnt,
|
|
w_evt.mois,
|
|
w_evt.date_debut,
|
|
w_evt.date_fin,
|
|
w_evt.cnt_date_debut,
|
|
w_evt.cnt_date_fin,
|
|
w_evt.bul,
|
|
w_evt.bul_date_debut,
|
|
w_evt.bul_date_fin,
|
|
w_evt.est_hors_periode,
|
|
coalesce(w_cnt_ttt.etp_cnt, 0) AS etp_cnt,
|
|
|
|
-- Données du Profil CTI
|
|
coalesce(w_cnt_csp.csp_code_original, chr(1)||'*') AS categorie_socio_professionnelle_code_original,
|
|
coalesce(w_cnt_csp.emp_code_original, chr(1)||'*') AS code_emploi_code_original,
|
|
chr(1)||'*' as grille_code_original, -- Dans le cas où le coeff contrat n'est pas juste, utiliser celui issu des bulletins (x_mode à true).
|
|
chr(1)||'*' AS grille_groupe_code_original,
|
|
chr(1)||'*' AS groupe_cotisant_code_original,
|
|
coalesce(w_cnt.motif_debut, chr(1)||'*') AS motif_debut_code_original,
|
|
coalesce(w_cnt.motif_fin, chr(1)||'*') AS motif_fin_code_original,
|
|
coalesce(w_cnt_qua.qua_code_original, chr(1)||'*') AS qualification_code_original,
|
|
coalesce(w_cnt_ufs.uf_code_original, chr(1)||'*') AS service_code_original,
|
|
chr(1)||'*' AS societe_interim_code_original,
|
|
coalesce(xta_saeq.code, chr(1)||'*') AS specialite_code_original,
|
|
coalesce(w_cnt_csp.statut_code_original, chr(1)||'*') AS statut_code_original,
|
|
coalesce(w_cnt.type_contrat, chr(1)||'*') AS type_contrat_code_original,
|
|
coalesce(w_cnt_tho.tho_code_original, chr(1)||'*') AS type_horaire_code_original,
|
|
coalesce(w_cnt_ttt.ttt_code_original, chr(1)||'*') AS type_temps_travail_code_original,
|
|
coalesce(w_cnt_ufs.cec_code_original, chr(1)||'*') AS section_analytique_code_original,
|
|
w_cnt.uf_localisation AS section_analytique_paie_code_original, -- UF de Localisation.
|
|
-- Champs dédiés au public.
|
|
chr(1)||'*' AS unite_fonctionnelle_code_original,
|
|
chr(1)||'*' AS categorie_conge_code_original,
|
|
chr(1)||'*' AS compte_salarie_code_original,
|
|
chr(1)||'*' AS commission_paritaire_code_original,
|
|
chr(1)||'*' AS lettre_budgetaire_code_original,
|
|
chr(1)||'*' AS cadre_emploi_code_original,
|
|
chr(1)||'*' AS filiere_code_original,
|
|
chr(1)||'*' AS categorie_statutaire_code_original
|
|
FROM w_evt
|
|
JOIN w_sal_oid on w_sal_oid.sal_mat = w_evt.mat
|
|
LEFT JOIN w_cnt ON w_cnt.cnt = w_evt.cnt
|
|
LEFT join w_cnt_csp on w_cnt_csp.csp_num = w_evt.csp_num
|
|
LEFT join w_cnt_ufs on w_cnt_ufs.ufs_num = w_evt.ufs_num
|
|
LEFT join w_cnt_qua on w_cnt_qua.qua_num = w_evt.qua_num
|
|
left join prod_pleiades2.xsalinfosdivers on xsalinfosdivers.salarie = w_sal_oid.sal_oid
|
|
left join prod_pleiades2.xta_saeq on xta_saeq.oid = xsalinfosdivers.xta_saeq
|
|
LEFT join w_cnt_ttt on w_cnt_ttt.ttt_num = w_evt.ttt_num
|
|
LEFT join w_cnt_tho on w_cnt_tho.tho_num = w_evt.tho_num
|
|
WHERE 1=1
|
|
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
|
|
;
|
|
|
|
]]></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,
|
|
salarie.prenom1 as prenom,
|
|
salarie.nom_usuel as nom,
|
|
salarie.nompatronymique as nom_naissance,
|
|
salnaissance.naissancedate::date as date_naissance,
|
|
case when sexe.code = 'M' then 'M' else 'F' end as sexe,
|
|
salarie.matricule as matricule,
|
|
salarie.matricule as code,
|
|
salarie.oid as code_original,
|
|
0 as entreprise_id,
|
|
coalesce(t_nationalites.oid, 0) as nationalite_id,
|
|
coalesce((max(ARRAY[extract(epoch from saladresse.end_date), t_codes_postaux.oid]))[2], 0) as code_postal_id,
|
|
coalesce((max(ARRAY[extract(epoch from salmatrimonial.end_date), t_situations_famille.oid]))[2], 0) as situation_famille_id,
|
|
coalesce((max(ARRAY[extract(epoch from relatdatefin), profil_id]))[2], 0) as profil_id,
|
|
max(relatdatedeb) as date_debut,
|
|
max(relatdatefin) as date_fin,
|
|
min(relatdatedeb) as date_entree_ets,
|
|
max(relatdatefin) as date_sortie_ets,
|
|
-- Champs dédiés au public.
|
|
null::date AS date_entree_fp,
|
|
null::date AS date_entree_fph,
|
|
0 AS no_adeli,
|
|
0 AS code_cotisation_id,
|
|
0 AS matricule_retraite
|
|
from prod_pleiades2.salarie
|
|
left join prod_pleiades2.sexe on sexe.oid = salarie.sexe
|
|
left join prod_pleiades2.salmatrimonial on salmatrimonial.matrimmatricule = salarie.oid
|
|
left join prod_pleiades2.salnaissance on salnaissance.naimatricule = salarie.oid
|
|
left join rh.t_situations_famille on t_situations_famille.code_original = salmatrimonial.matrimsituation -- ta_matrimonial
|
|
left join prod_pleiades2.nationalite on nationalite.oid = salarie.nationalite
|
|
left join rh.t_nationalites on t_nationalites.code_original = nationalite.code
|
|
left join prod_pleiades2.saladresse on saladresse.adrmatricule = salarie.oid
|
|
left join rh.t_codes_postaux ON t_codes_postaux.code = saladresse.codepostal
|
|
left join prod_pleiades2.relationcontrat on relationcontrat.relatmatricule = salarie.oid
|
|
left join w_profils on w_profils.mat = salarie.matricule
|
|
GROUP BY 1,2,3,4,5,6,7,8,9,10,11
|
|
;
|
|
|
|
]]></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,
|
|
salarie_remplace_id,
|
|
anciennete_anterieure_jours,
|
|
anciennete_anterieure_calculee_mois,
|
|
profil_id) -- dernier profil connu.
|
|
SELECT
|
|
p_salaries.oid AS salarie_id,
|
|
w_cnt.date_debut,
|
|
w_cnt.date_fin,
|
|
w_cnt.cnt as numero_contrat,
|
|
w_cnt.cnt AS code_original,
|
|
coalesce(t_etablissements.oid, 0) AS etablissement_id,
|
|
coalesce(rmp.oid, 0) as salarie_remplace_id,
|
|
w_cnt.anciennete_anterieure_jours,
|
|
w_cnt.anciennete_anterieure_calculee_mois,
|
|
coalesce((max(ARRAY[extract(epoch from w_profils.date_fin), w_profils.profil_id]))[2], 0) AS profil_id
|
|
FROM w_cnt
|
|
JOIN rh.p_salaries ON p_salaries.matricule = w_cnt.mat
|
|
LEFT JOIN rh.t_etablissements ON t_etablissements.code_original = w_cnt.etablissement
|
|
LEFT JOIN rh.p_salaries as rmp ON rmp.matricule = w_cnt.mat_remp
|
|
LEFT JOIN w_profils ON w_profils.cnt = w_cnt.cnt
|
|
GROUP BY 1,2,3,4,5,6,7,8,9
|
|
;
|
|
|
|
-- Ventilation des contrats par mois
|
|
TRUNCATE rh.p_contrats_mois
|
|
;
|
|
|
|
ALTER SEQUENCE rh.s_contrats_mois RESTART WITH 1
|
|
;
|
|
|
|
INSERT INTO rh.p_contrats_mois(
|
|
salarie_id,
|
|
contrat_id,
|
|
mois_activite,
|
|
date_debut,
|
|
date_fin,
|
|
nombre_entrees,
|
|
nombre_departs,
|
|
nombre_debut_contrat,
|
|
nombre_fin_contrat,
|
|
est_hors_periode,
|
|
present_debut_mois,
|
|
present_fin_mois,
|
|
equivalent_temps_plein,
|
|
age_id,
|
|
age_jours,
|
|
anciennete_jours,
|
|
anciennete_mois,
|
|
anciennete_annee_id,
|
|
profil_id
|
|
)
|
|
SELECT
|
|
p_contrats.salarie_id AS salarie_id,
|
|
p_contrats.oid AS contrat_id,
|
|
w_profils.mois AS mois,
|
|
w_profils.date_debut,
|
|
w_profils.date_fin,
|
|
CASE WHEN p_salaries.date_entree_ets BETWEEN w_profils.date_debut AND w_profils.date_fin THEN 1 ELSE 0 END AS nombre_entrees,
|
|
CASE WHEN p_salaries.date_sortie_ets BETWEEN w_profils.date_debut AND w_profils.date_fin THEN 1 ELSE 0 END AS nombre_departs,
|
|
CASE WHEN p_contrats.date_debut BETWEEN w_profils.date_debut AND w_profils.date_fin THEN 1 ELSE 0 END AS nombre_debut_contrat,
|
|
CASE WHEN p_contrats.date_fin BETWEEN w_profils.date_debut AND w_profils.date_fin THEN 1 ELSE 0 END AS nombre_fin_contrat,
|
|
est_hors_periode,
|
|
CASE WHEN base.cti_first_day(w_profils.date_debut) BETWEEN w_profils.date_debut AND w_profils.date_fin THEN 1 ELSE 0 END AS present_debut_mois,
|
|
CASE WHEN base.cti_last_day(w_profils.date_fin) BETWEEN w_profils.date_debut AND w_profils.date_fin THEN 1 ELSE 0 END AS present_fin_mois,
|
|
w_profils.etp_cnt AS equivalent_temps_plein,
|
|
base.cti_age(LEAST(w_profils.date_fin, p_contrats.date_fin), COALESCE(p_salaries.date_naissance, '1962-04-18'::date), 'ny') AS age_id,
|
|
LEAST(w_profils.date_fin, p_contrats.date_fin)::date - COALESCE(p_salaries.date_naissance, '1962-04-18'::date) AS age_jours,
|
|
-- Ancienneté en jours
|
|
p_contrats.anciennete_anterieure_jours
|
|
+ (w_profils.date_fin - p_contrats.date_debut)
|
|
+ 1 AS anciennete_jours,
|
|
-- Ancienneté en mois
|
|
p_contrats.anciennete_anterieure_calculee_mois
|
|
+ base.cti_age(date_trunc('month', w_profils.date_fin::date)::date, date_trunc('month', p_contrats.date_debut)::date, 'nm')
|
|
+ 1 AS anciennete_mois,
|
|
-- Ancienneté en années
|
|
floor(
|
|
(p_contrats.anciennete_anterieure_calculee_mois / 12)
|
|
+ (base.cti_age(date_trunc('month',w_profils.date_fin::date)::date, date_trunc('month',p_contrats.date_debut)::date, 'nm') + 1) / 12
|
|
) AS anciennete_annee_id,
|
|
0
|
|
FROM w_profils
|
|
JOIN w_cnt ON w_cnt.cnt = w_profils.cnt
|
|
JOIN rh.p_contrats ON p_contrats.numero_contrat = w_cnt.cnt
|
|
JOIN rh.p_salaries ON p_contrats.salarie_id = p_salaries.oid
|
|
JOIN rh.t_etablissements ON p_contrats.etablissement_id = t_etablissements.oid
|
|
--JOIN rh.t_entreprises ON t_etablissements.entreprise_id = t_entreprises.oid
|
|
GROUP BY 1,2,3,4,5,6,7,8,9,10,11,12,13,14,15,16,17,18,19
|
|
;
|
|
|
|
]]></sqlcmd>
|
|
</NODE>
|
|
<NODE label="Historique de la paie">
|
|
<sqlcmd><![CDATA[
|
|
|
|
-- Création des tables listant les rubriques de brut, cot, ...
|
|
DROP TABLE IF EXISTS w_rub_brut
|
|
;
|
|
CREATE TEMP TABLE w_rub_brut AS
|
|
with rub as (
|
|
select
|
|
begin_date::date as date_debut,
|
|
coalesce(nullif(end_date::date, '29990101'::date), '2099-12-31'::date) as date_fin,
|
|
poste_paie.code as rub,
|
|
case cumulassiette.code
|
|
when '+' then 1
|
|
when '-' then -1
|
|
when '0' then 0
|
|
end as signe
|
|
from prod_pleiades2.assiettetdp
|
|
join prod_pleiades2.ass on ass.oid = assiettetdp.assiette
|
|
join prod_pleiades2.cumulassiette on cumulassiette.oid = assiettetdp.codecumul
|
|
join prod_pleiades2.poste_paie on poste_paie.oid = assiettetdp.postepaie
|
|
where true
|
|
and ass.code = '001'
|
|
and cumulassiette.code != '0') -- on ne veut pas de ligne de paie lorsque la rubrique est inactive.
|
|
select
|
|
rub,
|
|
signe,
|
|
date_debut,
|
|
date_fin
|
|
from rub
|
|
where rub != '0965' -- il ne faut pas remonter le complément de gratification qui n'est pas compté dans le brut (6001).
|
|
;
|
|
|
|
DROP TABLE IF EXISTS w_rub_cotsal
|
|
;
|
|
CREATE TEMP TABLE w_rub_cotsal AS
|
|
with rub as (
|
|
select
|
|
begin_date::date as date_debut,
|
|
coalesce(nullif(end_date::date, '29990101'::date), '2099-12-31'::date) as date_fin,
|
|
poste_paie.code as rub,
|
|
case cumulassiette.code
|
|
when '+' then 1
|
|
when '-' then -1
|
|
when '0' then 0
|
|
end as signe
|
|
from prod_pleiades2.assiettetdp
|
|
join prod_pleiades2.ass on ass.oid = assiettetdp.assiette
|
|
join prod_pleiades2.cumulassiette on cumulassiette.oid = assiettetdp.codecumul
|
|
join prod_pleiades2.poste_paie on poste_paie.oid = assiettetdp.postepaie
|
|
where true
|
|
and ass.code = '015'
|
|
and cumulassiette.code != '0')
|
|
select
|
|
rub,
|
|
signe,
|
|
date_debut,
|
|
date_fin
|
|
from rub
|
|
;
|
|
|
|
DROP TABLE IF EXISTS w_rub_cotpat
|
|
;
|
|
CREATE TEMP TABLE w_rub_cotpat AS
|
|
with rub as (
|
|
select
|
|
begin_date::date as date_debut,
|
|
coalesce(nullif(end_date::date, '29990101'::date), '2099-12-31'::date) as date_fin,
|
|
poste_paie.code as rub,
|
|
case cumulassiette.code
|
|
when '+' then 1
|
|
when '-' then -1
|
|
when '0' then 0
|
|
end as signe
|
|
from prod_pleiades2.assiettetdp
|
|
join prod_pleiades2.ass on ass.oid = assiettetdp.assiette
|
|
join prod_pleiades2.cumulassiette on cumulassiette.oid = assiettetdp.codecumul
|
|
join prod_pleiades2.poste_paie on poste_paie.oid = assiettetdp.postepaie
|
|
where true
|
|
and ass.code = '014'
|
|
and cumulassiette.code != '0'),
|
|
rub_ts as (
|
|
select
|
|
begin_date::date as date_debut,
|
|
coalesce(nullif(end_date::date, '29990101'::date), '2099-12-31'::date) as date_fin,
|
|
poste_paie.code as rub,
|
|
case cumulassiette.code
|
|
when '+' then 1
|
|
when '-' then -1
|
|
when '0' then 0
|
|
end as signe
|
|
from prod_pleiades2.assiettetdp
|
|
join prod_pleiades2.ass on ass.oid = assiettetdp.assiette
|
|
join prod_pleiades2.cumulassiette on cumulassiette.oid = assiettetdp.codecumul
|
|
join prod_pleiades2.poste_paie on poste_paie.oid = assiettetdp.postepaie
|
|
where true
|
|
and ass.code = '225'
|
|
and cumulassiette.code != '0')
|
|
-- end with
|
|
select
|
|
rub,
|
|
signe,
|
|
date_debut,
|
|
date_fin
|
|
from rub
|
|
where true
|
|
and rub != '8690' -- on veut le détail de la 8690 "Autres ch. patronales".
|
|
and rub != '6829' -- La 6829 contient une erreur de paramétrage (oubli de pleiades). On la force sur toute la période à la suite de cette même requête. @todo corrigée depuis janvier 2016.
|
|
and rub not in ('6790', '7208') -- on ne veut pas remonter ces charges patronales. @todo corrigée depuis janvier 2016.
|
|
UNION
|
|
select
|
|
rub,
|
|
signe,
|
|
date_debut,
|
|
date_fin
|
|
from rub_ts
|
|
where rub != '8569' -- on veut le détail de la 8569 "TOTAL Taxe sur les salaires".
|
|
UNION
|
|
select
|
|
unnest(array['8562', '8565', '8567', '8568']) as rub, -- Détail de la taxe sur les salaires.
|
|
1 as signe,
|
|
'19700101'::date as date_debut,
|
|
'20991231'::date as date_fin
|
|
UNION
|
|
select
|
|
'6829' as rub, -- 6829 "majoration allocations familiales" forcées sur toute la période car erreur de paramétrage dans pleiades. @todo corrigée depuis janvier 2016.
|
|
1 as signe,
|
|
'19700101'::date as date_debut,
|
|
'20991231'::date as date_fin
|
|
UNION
|
|
select
|
|
'6795' as rub, -- 6795 ou 6780 "Allégement Fillon". @todo corrigée depuis janvier 2016
|
|
1 as signe,
|
|
'19700101'::date as date_debut,
|
|
'20991231'::date as date_fin
|
|
;
|
|
|
|
DROP TABLE IF EXISTS w_rub_netimpos
|
|
;
|
|
CREATE TEMP TABLE w_rub_netimpos AS
|
|
with rub as (
|
|
select
|
|
begin_date::date as date_debut,
|
|
coalesce(nullif(end_date::date, '29990101'::date), '2099-12-31'::date) as date_fin,
|
|
poste_paie.code as rub,
|
|
case cumulassiette.code
|
|
when '+' then 1
|
|
when '-' then -1
|
|
when '0' then 0
|
|
end as signe
|
|
from prod_pleiades2.assiettetdp
|
|
join prod_pleiades2.ass on ass.oid = assiettetdp.assiette
|
|
join prod_pleiades2.cumulassiette on cumulassiette.oid = assiettetdp.codecumul
|
|
join prod_pleiades2.poste_paie on poste_paie.oid = assiettetdp.postepaie
|
|
where true
|
|
and ass.code = '002'
|
|
and cumulassiette.code != '0')
|
|
-- end with
|
|
select
|
|
rub.rub,
|
|
rub.signe,
|
|
rub.date_debut,
|
|
rub.date_fin
|
|
from rub
|
|
left join w_rub_brut on w_rub_brut.rub = rub.rub
|
|
where true
|
|
and w_rub_brut.rub is null -- on sélectionne uniquement les rubriques pas déjà prises du brut.
|
|
and rub.rub not in ('6000', '6001', '5613') -- on sort les rubriques de cumul du brut ainsi que la 5613 qui n'est pas imposable.
|
|
UNION
|
|
select
|
|
rub,
|
|
signe,
|
|
date_debut,
|
|
date_fin
|
|
from w_rub_brut
|
|
where rub != '5613'
|
|
;
|
|
|
|
DROP TABLE IF EXISTS w_rub_netpayer
|
|
;
|
|
CREATE TEMP TABLE w_rub_netpayer AS
|
|
with rub as (
|
|
select
|
|
begin_date::date as date_debut,
|
|
coalesce(nullif(end_date::date, '29990101'::date), '2099-12-31'::date) as date_fin,
|
|
poste_paie.code as rub,
|
|
case cumulassiette.code
|
|
when '+' then 1
|
|
when '-' then -1
|
|
when '0' then 0
|
|
end as signe
|
|
from prod_pleiades2.assiettetdp
|
|
join prod_pleiades2.ass on ass.oid = assiettetdp.assiette
|
|
join prod_pleiades2.cumulassiette on cumulassiette.oid = assiettetdp.codecumul
|
|
join prod_pleiades2.poste_paie on poste_paie.oid = assiettetdp.postepaie
|
|
where true
|
|
and ass.code = '003'
|
|
and cumulassiette.code != '0')
|
|
-- end with
|
|
select
|
|
rub.rub,
|
|
rub.signe,
|
|
rub.date_debut,
|
|
rub.date_fin
|
|
from rub
|
|
left join w_rub_brut on w_rub_brut.rub = rub.rub
|
|
where true
|
|
and w_rub_brut.rub is null -- on sélectionne uniquement les rubriques pas déjà prises du brut.
|
|
and rub.rub not in ('6000', '6001') -- on sort les rubriques de cumul du brut.
|
|
UNION
|
|
select
|
|
rub,
|
|
signe,
|
|
date_debut,
|
|
date_fin
|
|
from w_rub_brut
|
|
;
|
|
|
|
DROP TABLE IF EXISTS w_rub_heures
|
|
;
|
|
CREATE TEMP TABLE w_rub_heures AS
|
|
with rub as (
|
|
select
|
|
begin_date::date as date_debut,
|
|
coalesce(nullif(end_date::date, '29990101'::date), '2099-12-31'::date) as date_fin,
|
|
poste_paie.code as rub,
|
|
valeurcomposass.code = 'M' as montant, -- true = montant; false = base.
|
|
case cumulassiette.code
|
|
when '+' then 1
|
|
when '-' then -1
|
|
when '0' then 0
|
|
end as signe
|
|
from prod_pleiades2.assiettetdp
|
|
join prod_pleiades2.ass on ass.oid = assiettetdp.assiette
|
|
join prod_pleiades2.cumulassiette on cumulassiette.oid = assiettetdp.codecumul
|
|
join prod_pleiades2.valeurcomposass on valeurcomposass.oid = assiettetdp.codevaleur
|
|
join prod_pleiades2.poste_paie on poste_paie.oid = assiettetdp.postepaie
|
|
where true
|
|
and ass.code = '210'
|
|
and cumulassiette.code != '0')
|
|
select
|
|
rub,
|
|
montant,
|
|
signe,
|
|
date_debut,
|
|
date_fin
|
|
from rub
|
|
where rub != '6033' -- il faut retirer "PLAFOND ETUDIANT INTERNE" pour être juste.
|
|
UNION
|
|
select
|
|
'9953'::text as rub,
|
|
true as montant,
|
|
1 as signe,
|
|
'19700101'::date as date_debut,
|
|
'20991231'::date as date_fin
|
|
UNION
|
|
select
|
|
unnest(array[
|
|
-- '4599',
|
|
-- '4600',
|
|
'4601',
|
|
-- '4602',
|
|
-- '4603',
|
|
'4604',
|
|
'4621',
|
|
'4622',
|
|
'4623',
|
|
'4624',
|
|
'4625',
|
|
'4626'
|
|
]) as rub,
|
|
false as montant,
|
|
-1 as signe,
|
|
'19700101'::date as date_debut,
|
|
'20991231'::date as date_fin
|
|
UNION
|
|
select
|
|
'5439' as rub,
|
|
true as montant,
|
|
-1 as signe,
|
|
'19700101'::date as date_debut,
|
|
'20991231'::date as date_fin
|
|
;
|
|
|
|
drop table if exists w_rub_h_2
|
|
;
|
|
create temp table w_rub_h_2 as
|
|
select
|
|
null::text as rub,
|
|
null::boolean as is_montant,
|
|
null::int as signe
|
|
limit 0
|
|
;
|
|
insert into w_rub_h_2 values
|
|
('0300',true,'1'),
|
|
('0301',true,'1'),
|
|
('0340',true,'1'),
|
|
('0341',true,'1'),
|
|
('0859',true,'1'),
|
|
('3047',true,'1'),
|
|
('4674',false,'-1'),
|
|
('4676',false,'-1'),
|
|
('4678',false,'-1'),
|
|
('4702',false,'-1'),
|
|
('4704',false,'-1'),
|
|
('4794',false,'-1'),
|
|
('4796',false,'1'),
|
|
('4800',false,'-1'),
|
|
('4803',false,'1'),
|
|
('5203',true,'1'),
|
|
('5206',true,'1'),
|
|
('5208',true,'-1'),
|
|
('5217',true,'1'),
|
|
('5218',true,'1'),
|
|
('5415',false,'1'),
|
|
('5416',false,'1'),
|
|
('5417',false,'1'),
|
|
('5418',false,'1'),
|
|
('5419',false,'1'),
|
|
('5425',false,'1'),
|
|
('5426',false,'1'),
|
|
('5427',false,'1'),
|
|
('5434',false,'1'),
|
|
('5436',false,'1'),
|
|
('5439',true,'-1')
|
|
;
|
|
|
|
-- OD/Net Patronal d'après une liste établissement IMP_ODN_PAT.
|
|
drop table if exists w_rub_odnet_pat
|
|
;
|
|
create temp table w_rub_odnet_pat as
|
|
select t_rubriques.code as rub
|
|
from rh.t_listes
|
|
join rh.t_listes_contenu on t_listes_contenu.liste_id = t_listes.oid
|
|
join rh.t_rubriques on t_rubriques.oid = t_listes_contenu.to_id
|
|
where t_listes.code = 'IMP_ODN_PAT'
|
|
;
|
|
|
|
-- Heures DADS pour Bilan Social (rubrique de cumul 6020; assiette 210).
|
|
DROP TABLE IF EXISTS w_rub_heures_dads
|
|
;
|
|
CREATE TEMP TABLE w_rub_heures_dads AS
|
|
select
|
|
'6020'::text as rub,
|
|
true as montant,
|
|
1 as signe,
|
|
'19700101'::date as date_debut,
|
|
'20991231'::date as date_fin
|
|
;
|
|
|
|
DROP TABLE IF EXISTS w_asso_comptes
|
|
;
|
|
|
|
CREATE TEMP TABLE w_asso_comptes AS
|
|
select
|
|
w_hp.hp_ctid,
|
|
0::bigint as compte_id
|
|
from w_hp
|
|
;
|
|
|
|
CREATE INDEX i_asso_comptes_0 ON w_asso_comptes USING btree(hp_ctid)
|
|
;
|
|
|
|
CREATE INDEX i_asso_comptes_1 ON w_asso_comptes USING btree(compte_id)
|
|
;
|
|
|
|
WITH subq AS (
|
|
select
|
|
w_hp.hp_ctid,
|
|
max(cpt_e5.oid) as compte_id
|
|
from w_hp
|
|
-- Association rubriques <=> comptes e5.
|
|
join w_compte on true
|
|
and w_compte.matricule = w_hp.mat
|
|
and w_compte.poste = w_hp.rub
|
|
and w_compte.periode_imputation = w_hp.mois
|
|
and w_compte.periode_origine||w_compte.sous_periode = substr(w_hp.sous_periode, 3, 4)||substr(w_hp.sous_periode, 8, 2)
|
|
join rh.t_compte as cpt_e5 on cpt_e5.code_original = w_compte.compte
|
|
group by 1)
|
|
UPDATE w_asso_comptes SET
|
|
compte_id = subq.compte_id
|
|
FROM subq
|
|
WHERE 1=1
|
|
AND w_asso_comptes.hp_ctid = subq.hp_ctid
|
|
AND w_asso_comptes.compte_id = 0
|
|
;
|
|
|
|
WITH subq AS (
|
|
select
|
|
w_hp.hp_ctid,
|
|
max(cpt_e5_bis.oid) as compte_id
|
|
from w_hp
|
|
-- Association rubriques <=> comptes e5.
|
|
join w_compte as w_compte2 on true
|
|
and w_compte2.matricule = w_hp.mat
|
|
and w_compte2.poste = w_hp.rub
|
|
and w_compte2.periode_imputation = w_hp.mois
|
|
and @w_compte2.montant_total = @w_hp.mt
|
|
join rh.t_compte as cpt_e5_bis on cpt_e5_bis.code_original = w_compte2.compte
|
|
group by 1)
|
|
UPDATE w_asso_comptes SET
|
|
compte_id = subq.compte_id
|
|
FROM subq
|
|
WHERE 1=1
|
|
AND w_asso_comptes.hp_ctid = subq.hp_ctid
|
|
AND w_asso_comptes.compte_id = 0
|
|
;
|
|
|
|
WITH subq AS (
|
|
select
|
|
w_hp.hp_ctid,
|
|
max(cpt_e5_ter.oid) as compte_id
|
|
from w_hp
|
|
-- Association rubriques <=> comptes e5.
|
|
join w_compte as w_compte3 on true
|
|
and w_compte3.matricule = w_hp.mat
|
|
and w_compte3.poste = w_hp.rub
|
|
and w_compte3.periode_imputation = w_hp.mois
|
|
and @w_compte3.montant = @w_hp.montant_total
|
|
join rh.t_compte as cpt_e5_ter on cpt_e5_ter.code_original = w_compte3.compte
|
|
group by 1)
|
|
UPDATE w_asso_comptes SET
|
|
compte_id = subq.compte_id
|
|
FROM subq
|
|
WHERE 1=1
|
|
AND w_asso_comptes.hp_ctid = subq.hp_ctid
|
|
AND w_asso_comptes.compte_id = 0
|
|
;
|
|
|
|
WITH subq AS (
|
|
select
|
|
w_hp.hp_ctid,
|
|
max(cpt_e5_qua.oid) as compte_id
|
|
from w_hp
|
|
-- Association rubriques <=> comptes e5.
|
|
join w_compte as w_compte4 on true
|
|
and w_compte4.matricule = w_hp.mat
|
|
and w_compte4.poste = w_hp.rub
|
|
and w_compte4.periode_imputation = w_hp.mois
|
|
and @w_compte4.montant_total = @w_hp.montant_total
|
|
join rh.t_compte as cpt_e5_qua on cpt_e5_qua.code_original = w_compte4.compte
|
|
group by 1)
|
|
UPDATE w_asso_comptes SET
|
|
compte_id = subq.compte_id
|
|
FROM subq
|
|
WHERE 1=1
|
|
AND w_asso_comptes.hp_ctid = subq.hp_ctid
|
|
AND w_asso_comptes.compte_id = 0
|
|
;
|
|
|
|
ALTER SEQUENCE rh.s_historique_paie RESTART WITH 1
|
|
;
|
|
|
|
DROP TABLE IF EXISTS w_historique_paie
|
|
;
|
|
|
|
CREATE TEMP TABLE w_historique_paie AS
|
|
select
|
|
w_hp.hp_ctid, -- permet d'être sûr qu'on n'agrège pas à tort des lignes de paie w_hp.
|
|
date_part('year', age(w_bul.date_fin, date_naissance)) AS age_id,
|
|
w_hp.mat||w_hp.mois||(case when to_char(w_hp.date_debut, 'YYYYMM')::numeric = w_hp.mois then substring(w_hp.sous_periode, 8, 2) else '01' end), -- numero fictif de bulletin. Rang 01 lorsque régulation.
|
|
w_hp.mat,
|
|
w_hp.relatnum,
|
|
w_hp.mois::numeric as mois_paie,
|
|
w_bul.date_debut,
|
|
w_bul.date_fin,
|
|
w_bul.date_fin as date_paie,
|
|
substring(w_hp.sous_periode, 1, 6)::numeric as mois_activite,
|
|
date_virement,
|
|
t_rubriques.oid AS rubrique_id,
|
|
p_salaries.oid AS salarie_id,
|
|
w_hp.sous_periode,
|
|
w_hp.date_debut as date_debut_ori,
|
|
w_hp.date_fin as date_fin_ori,
|
|
w_hp.rub,
|
|
w_bul.bul,
|
|
w_hp.mt * coalesce(w_rub_brut.signe, w_rub_cotpat.signe, w_rub_netpayer.signe) as ori_mt, -- orienté masse salariale à cause du signe.
|
|
w_hp.montant_total * coalesce(w_rub_brut.signe, w_rub_cotpat.signe, w_rub_netpayer.signe) as montant_total, -- orienté masse salariale à cause du signe.
|
|
w_hp.montant_total_imputation * coalesce(w_rub_brut.signe, w_rub_cotpat.signe, w_rub_netpayer.signe) as montant_total_imputation, -- orienté masse salariale à cause du signe.
|
|
case
|
|
when w_rub_h_2.rub is not null then
|
|
case w_rub_h_2.is_montant
|
|
when true then w_hp.mt * w_rub_h_2.signe
|
|
when false then (case when w_hp.mt = 0 then 0 else w_hp.base end)
|
|
end
|
|
when w_rub_heures_dads.rub is not null then w_hp.mt -- on injecte la rubrique de cumul des heures DADS dans l'indicateur iCTI "base".
|
|
else w_hp.base
|
|
end as base,
|
|
case
|
|
when w_rub_h_2.rub is not null then
|
|
case w_rub_h_2.is_montant
|
|
when true then w_hp.montant_total * w_rub_h_2.signe
|
|
when false then (case when w_hp.montant_total = 0 then 0 else w_hp.base_total end)
|
|
end
|
|
when w_rub_heures_dads.rub is not null then w_hp.montant_total -- on injecte la rubrique de cumul des heures DADS dans l'indicateur iCTI "base".
|
|
else w_hp.base_total
|
|
end as base_total,
|
|
case
|
|
when w_rub_h_2.rub is not null then
|
|
case w_rub_h_2.is_montant
|
|
when true then w_hp.montant_total_imputation * w_rub_h_2.signe
|
|
when false then (case when w_hp.montant_total_imputation = 0 then 0 else w_hp.base_total_imputation end)
|
|
end
|
|
when w_rub_heures_dads.rub is not null then w_hp.montant_total_imputation -- on injecte la rubrique de cumul des heures DADS dans l'indicateur iCTI "base".
|
|
else w_hp.base_total_imputation
|
|
end as base_total_imputation,
|
|
case when w_rub_brut.rub is not null then w_hp.mt * w_rub_brut.signe else 0 end as montant_brut,
|
|
case when w_rub_cotsal.rub is not null then w_hp.tx else 0 end as taux_cotisation_salarie,
|
|
case when w_rub_cotsal.rub is not null then w_hp.mt * w_rub_cotsal.signe else 0 end as montant_cotisation_salarie,
|
|
case when w_rub_cotpat.rub is not null then w_hp.tx else 0 end as taux_cotisation_patronale,
|
|
case when w_rub_cotpat.rub is not null then w_hp.mt * w_rub_cotpat.signe else 0 end as montant_cotisation_patronale,
|
|
0 as montant_avantage_nature,
|
|
0 as montant_frais_imposables,
|
|
case when w_rub_netpayer.rub is not null then w_hp.mt * w_rub_netpayer.signe else 0 end as montant_net_a_payer_salarie,
|
|
case when w_rub_netimpos.rub is not null then w_hp.mt * w_rub_netimpos.signe else 0 end as montant_net_imposable_salarie,
|
|
0 as montant_od_net_salarie,
|
|
case when w_rub_odnet_pat.rub is not null then w_hp.mt * w_rub_netpayer.signe else 0 end as montant_od_net_patronale, -- on prend le signe du net à payer.
|
|
0 as organisme_cotisation_id,
|
|
w_asso_comptes.compte_id,
|
|
(max(array[extract(epoch from w_profils.date_debut), p_contrats.oid]))[2] AS contrat_id,
|
|
(max(array[extract(epoch from w_profils.date_debut), p_contrats_mois.oid]))[2] AS contrat_mois_id,
|
|
(max(array[extract(epoch from w_profils.date_debut), w_profils.profil_id]))[2] AS profil_id,
|
|
nextval('rh.s_historique_paie'::regclass) as oid
|
|
from w_hp
|
|
JOIN w_bul on w_bul.bul = w_hp.mat||w_hp.mois||(case when to_char(w_hp.date_debut, 'YYYYMM')::numeric = w_hp.mois then substring(sous_periode, 8, 2) else '01' end)
|
|
JOIN rh.t_rubriques ON t_rubriques.code_original = w_hp.rub
|
|
JOIN rh.p_salaries ON p_salaries.matricule = w_bul.mat
|
|
JOIN w_profils ON 1=1
|
|
AND w_profils.bul = w_bul.bul
|
|
AND w_profils.bul_date_debut = w_bul.date_debut
|
|
left join w_rub_brut on true
|
|
and w_rub_brut.rub = w_hp.rub
|
|
and w_hp.date_fin between w_rub_brut.date_debut and w_rub_brut.date_fin
|
|
left join w_rub_cotsal on true
|
|
and w_rub_cotsal.rub = w_hp.rub
|
|
and w_hp.date_fin between w_rub_cotsal.date_debut and w_rub_cotsal.date_fin
|
|
left join w_rub_cotpat on true
|
|
and w_rub_cotpat.rub = w_hp.rub
|
|
and w_hp.date_fin between w_rub_cotpat.date_debut and w_rub_cotpat.date_fin
|
|
left join w_rub_netimpos on true
|
|
and w_rub_netimpos.rub = w_hp.rub
|
|
and w_hp.date_fin between w_rub_netimpos.date_debut and w_rub_netimpos.date_fin
|
|
left join w_rub_netpayer on true
|
|
and w_rub_netpayer.rub = w_hp.rub
|
|
and w_hp.date_fin between w_rub_netpayer.date_debut and w_rub_netpayer.date_fin
|
|
left join w_rub_h_2 on true
|
|
and w_rub_h_2.rub = w_hp.rub
|
|
--and w_hp.date_fin between w_rub_heures.date_debut and w_rub_heures.date_fin
|
|
left join w_rub_heures_dads on true
|
|
and w_rub_heures_dads.rub = w_hp.rub
|
|
left join w_asso_comptes on w_asso_comptes.hp_ctid = w_hp.hp_ctid
|
|
LEFT JOIN rh.p_contrats on p_contrats.numero_contrat = w_profils.cnt
|
|
LEFT JOIN rh.p_contrats_mois on 1=1
|
|
AND p_contrats_mois.contrat_id = p_contrats.oid
|
|
AND p_contrats_mois.mois_activite = w_bul.mois
|
|
left join w_rub_odnet_pat on w_rub_odnet_pat.rub = w_hp.rub
|
|
where true
|
|
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,
|
|
w_rub_h_2.rub, w_rub_h_2.is_montant, w_rub_heures_dads.rub, w_rub_brut.rub, w_rub_cotsal.rub, w_rub_cotpat.rub, w_rub_netpayer.rub, w_rub_netimpos.rub, w_hp.mt, w_hp.base
|
|
HAVING 1!=1
|
|
OR case when w_rub_h_2.rub is not null then 1 else 0 end != 0
|
|
OR case when w_rub_heures_dads.rub is not null then 1 else 0 end != 0
|
|
OR case when w_rub_brut.rub is not null then w_hp.mt else 0 end != 0
|
|
OR case when w_rub_cotpat.rub is not null then w_hp.mt else 0 end != 0
|
|
OR case when w_rub_cotsal.rub is not null then w_hp.mt else 0 end != 0
|
|
OR case when w_rub_netpayer.rub is not null then w_hp.mt else 0 end != 0
|
|
OR case when w_rub_netimpos.rub is not null then w_hp.mt else 0 end != 0
|
|
;
|
|
|
|
-- Associer les bulletins hors contrat (is null) avec le contrat précédent.
|
|
UPDATE w_historique_paie
|
|
SET contrat_id = subq.contrat_id,
|
|
contrat_mois_id = subq.contrat_mois_id
|
|
FROM (
|
|
select
|
|
w_historique_paie.oid,
|
|
(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
|
|
from w_historique_paie
|
|
join rh.p_contrats_mois on true
|
|
and p_contrats_mois.salarie_id = w_historique_paie.salarie_id
|
|
and p_contrats_mois.date_fin < w_historique_paie.date_debut
|
|
where contrat_mois_id is null
|
|
group by 1) as subq
|
|
WHERE true
|
|
AND w_historique_paie.oid = subq.oid
|
|
AND w_historique_paie.contrat_mois_id is null
|
|
;
|
|
|
|
SELECT base.cti_stash_table_constraints('rh.p_historique_paie')
|
|
;
|
|
|
|
SELECT base.cti_stash_table_indexes('rh.p_historique_paie')
|
|
;
|
|
|
|
TRUNCATE rh.p_historique_paie
|
|
;
|
|
|
|
INSERT INTO rh.p_historique_paie (
|
|
oid,
|
|
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,
|
|
montant_od_net_patronale,
|
|
organisme_cotisation_id,
|
|
profil_id,
|
|
rubrique_id,
|
|
salarie_id,
|
|
taux_cotisation_patronale,
|
|
taux_cotisation_salarie,
|
|
compte_id)
|
|
SELECT
|
|
oid,
|
|
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,
|
|
montant_od_net_patronale,
|
|
organisme_cotisation_id,
|
|
profil_id,
|
|
rubrique_id,
|
|
salarie_id,
|
|
taux_cotisation_patronale,
|
|
taux_cotisation_salarie,
|
|
compte_id
|
|
FROM w_historique_paie
|
|
;
|
|
|
|
-- Inserer pour chaque bulletin une ligne qui va faire le compte avec le total
|
|
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,
|
|
profil_id,
|
|
rubrique_id,
|
|
salarie_id,
|
|
taux_cotisation_patronale,
|
|
taux_cotisation_salarie,
|
|
compte_id,
|
|
code_original)
|
|
SELECT
|
|
age_id,
|
|
0,
|
|
contrat_id,
|
|
contrat_mois_id,
|
|
subq.date_debut,
|
|
subq.date_fin,
|
|
subq.date_paie,
|
|
subq.mois_activite,
|
|
subq.mois_paie,
|
|
0,
|
|
sum(chi.montant_brut - subq.montant_brut),
|
|
0, -- sum(chi.montant_cotisation_patronale - subq.montant_cotisation_patronale), désactivé pour l'instant.
|
|
sum(chi.montant_cotisation_salarie - subq.montant_cotisation_salarie),
|
|
0,
|
|
sum(chi.montant_net_a_payer_salarie - subq.montant_net_a_payer_salarie),
|
|
sum(chi.montant_net_imposable_salarie - subq.montant_net_imposable_salarie),
|
|
0,
|
|
subq.organisme_cotisation_id,
|
|
subq.profil_id,
|
|
(SELECT oid FROM rh.t_rubriques WHERE code = 'C000'),
|
|
subq.salarie_id,
|
|
0,
|
|
0,
|
|
0,
|
|
0 -- Le code original est utilisé pour identifier quelle vague d'UPDATE a servi à faire la mise à jour (cf. plus bas).
|
|
FROM (
|
|
SELECT
|
|
hp.age_id,
|
|
hp.contrat_id,
|
|
hp.contrat_mois_id,
|
|
hp.date_debut,
|
|
hp.date_fin,
|
|
hp.date_paie,
|
|
hp.mois_paie as mois_activite, -- il ne faut pas mettre le mois d'activite sinon on a plusieurs lignes et la C000 est mal calculée.
|
|
hp.mois_paie,
|
|
sum(montant_brut) as montant_brut,
|
|
sum(montant_cotisation_patronale) as montant_cotisation_patronale,
|
|
sum(montant_cotisation_salarie) as montant_cotisation_salarie,
|
|
sum(montant_net_a_payer_salarie) as montant_net_a_payer_salarie,
|
|
sum(montant_net_imposable_salarie) as montant_net_imposable_salarie,
|
|
hp.organisme_cotisation_id,
|
|
hp.profil_id,
|
|
(SELECT oid FROM rh.t_rubriques WHERE code = 'C000'),
|
|
hp.salarie_id,
|
|
hp.bul
|
|
FROM w_historique_paie AS hp
|
|
JOIN rh.p_salaries ON p_salaries.oid = hp.salarie_id
|
|
GROUP BY 1,2,3,4,5,6,7,8, 14,15,16,17,18) as subq
|
|
JOIN rh.p_salaries ON p_salaries.oid = subq.salarie_id
|
|
JOIN w_chiffrier AS chi ON 1=1
|
|
AND chi.mat = p_salaries.matricule
|
|
AND chi.bul = subq.bul
|
|
AND chi.date_debut = subq.date_debut
|
|
AND chi.date_fin = subq.date_fin
|
|
GROUP BY 1,2,3,4,5,6,7,8,9,10, 14, 17,18,19,20,21,22,23
|
|
HAVING 1!=1
|
|
OR sum(chi.montant_brut - subq.montant_brut) != 0
|
|
-- OR sum(chi.montant_cotisation_patronale - subq.montant_cotisation_patronale) != 0 -- désactivé pour l'instant.
|
|
OR sum(chi.montant_cotisation_salarie - subq.montant_cotisation_salarie) != 0
|
|
OR sum(chi.montant_net_a_payer_salarie - subq.montant_net_a_payer_salarie) != 0
|
|
OR sum(chi.montant_net_imposable_salarie - subq.montant_net_imposable_salarie) != 0
|
|
;
|
|
|
|
]]></sqlcmd>
|
|
</NODE>
|
|
<NODE label="Ventilation des profils">
|
|
<sqlcmd><![CDATA[
|
|
|
|
-- Alimentation des profils simultanés.
|
|
TRUNCATE rh.p_profil_contrat_mois
|
|
;
|
|
|
|
INSERT INTO rh.p_profil_contrat_mois (
|
|
profil_id,
|
|
contrat_mois_id,
|
|
salarie_id,
|
|
ratio,
|
|
mois
|
|
)
|
|
SELECT
|
|
coalesce(w_profils.profil_id, 0) AS profil_id,
|
|
p_contrats_mois.oid AS contrat_mois_id,
|
|
p_contrats_mois.salarie_id,
|
|
1 AS ratio,
|
|
p_contrats_mois.mois_activite
|
|
FROM rh.p_contrats_mois
|
|
JOIN rh.p_salaries ON p_salaries.oid = p_contrats_mois.salarie_id
|
|
JOIN w_profils ON 1=1
|
|
--AND w_profils.profil_id = p_contrats_mois.profil_id
|
|
AND w_profils.mat = p_salaries.matricule
|
|
AND w_profils.date_debut = p_contrats_mois.date_debut
|
|
AND w_profils.date_fin = p_contrats_mois.date_fin
|
|
--and base.cti_overlaps
|
|
GROUP BY 1,2,3,4,5
|
|
;
|
|
|
|
]]></sqlcmd>
|
|
</NODE>
|
|
<NODE label="Ventilation Analytique">
|
|
<sqlcmd><![CDATA[
|
|
|
|
-- Liste exhaustive des rubriques pouvant faire l'objet d'une affectation forcée (fournie par M. Chastre).
|
|
DROP TABLE IF EXISTS w_exc_rub
|
|
;
|
|
|
|
CREATE TEMP TABLE w_exc_rub AS
|
|
SELECT unnest(ARRAY['5390', '5392', '5394', '5328', '5332', '5336', '5340', '5384', '5386', '5388', '5272', '5276', '5280', '5271', '5275', '5279']) as rub
|
|
;
|
|
|
|
-- Création de la table des ventilations corrigées.
|
|
DROP SEQUENCE IF EXISTS ventilation_id
|
|
;
|
|
CREATE TEMP SEQUENCE ventilation_id START 1
|
|
;
|
|
|
|
DROP TABLE IF EXISTS w_ven
|
|
;
|
|
|
|
CREATE TEMP TABLE w_ven AS
|
|
with ven_0 as (
|
|
select
|
|
replace(imputation, 'JR00', 'JH00') as imputation,
|
|
('20'||periode_imputation)::int as periode_imputation,
|
|
periode_origine,
|
|
matricule,
|
|
contrat,
|
|
poste,
|
|
compte,
|
|
sum(montant) as montant
|
|
from prod_pleiades2.a01_compta as a01_compta -- plus v_a01_compta car pas de notion de contrat avant 2017.
|
|
where 1=1
|
|
AND ecriture = 'C'
|
|
AND ('20'||periode_imputation)::int >= CONCAT(SPLIT_PART(rhp('rhprovider_start'), '-', 1), SPLIT_PART(rhp('rhprovider_start'), '-', 2))::int
|
|
group by 1,2,3,4,5,6,7
|
|
having sum(montant) is not null),
|
|
ven_1 as (
|
|
select
|
|
imputation,
|
|
periode_imputation,
|
|
periode_origine,
|
|
matricule,
|
|
contrat,
|
|
poste,
|
|
compte,
|
|
montant,
|
|
case sum(montant) over w1
|
|
when 0 then 1.0 / count(*) over w1
|
|
else round(base.cti_division(montant, sum(montant) over w1), 6)
|
|
end as ratio,
|
|
row_number() over w2 as rang
|
|
from ven_0
|
|
window w1 as (partition by matricule, contrat, periode_imputation, periode_origine, poste, compte),
|
|
w2 as (partition by matricule, contrat, periode_imputation, periode_origine, poste, compte order by montant desc)),
|
|
ven_corr as (
|
|
select
|
|
matricule,
|
|
contrat,
|
|
periode_imputation,
|
|
periode_origine,
|
|
poste,
|
|
compte,
|
|
1.0 - sum(ratio) as corr
|
|
from ven_1
|
|
group by 1,2,3,4,5,6
|
|
having sum(ratio) != 1),
|
|
ven_tot as (
|
|
select
|
|
ven_1.periode_imputation,
|
|
ven_1.periode_origine,
|
|
ven_1.matricule,
|
|
ven_1.contrat,
|
|
ven_1.poste,
|
|
ven_1.compte,
|
|
sum(ven_1.montant) as montant,
|
|
array_agg(ven_1.imputation order by ven_1.imputation) as imp,
|
|
array_agg(case when corr is not null and ven_1.rang = 1 then ven_1.ratio + ven_corr.corr else ven_1.ratio end order by ven_1.imputation) as rat,
|
|
nextval('ventilation_id') as ventilation_id
|
|
from ven_1
|
|
left join ven_corr on 1=1
|
|
and ven_corr.matricule = ven_1.matricule
|
|
and ven_corr.contrat = ven_1.contrat
|
|
and ven_corr.periode_imputation = ven_1.periode_imputation
|
|
and ven_corr.periode_origine = ven_1.periode_origine
|
|
and ven_corr.poste = ven_1.poste
|
|
and ven_corr.compte = ven_1.compte
|
|
group by 1,2,3,4,5,6)
|
|
select
|
|
periode_imputation,
|
|
periode_origine,
|
|
matricule,
|
|
contrat,
|
|
poste,
|
|
compte,
|
|
sum(montant) over w as montant_tot, -- sans periode_origine.
|
|
0 = ANY(array_agg(montant) over w) as contains_zero,-- indicateur qui permet de traiter le cas des sous-périodes != imputation avec des montant_det à 0.
|
|
montant as montant_det,
|
|
imp,
|
|
rat,
|
|
ventilation_id
|
|
from ven_tot
|
|
window w as (partition by matricule, contrat, periode_imputation, poste, compte)
|
|
;
|
|
|
|
-- Création de la table des ventilations corrigées 2 (avec totalisation à date d'imputation).
|
|
DROP TABLE IF EXISTS w_ven_imp
|
|
;
|
|
|
|
CREATE TEMP TABLE w_ven_imp AS
|
|
with ven_0 as (
|
|
select
|
|
replace(imputation, 'JR00', 'JH00') as imputation,
|
|
('20'||periode_imputation)::int as periode_imputation,
|
|
matricule,
|
|
contrat,
|
|
poste,
|
|
compte,
|
|
sum(montant) as montant
|
|
from prod_pleiades2.a01_compta as a01_compta -- plus v_a01_compta car pas de notion de contrat avant 2017.
|
|
where 1=1
|
|
AND ecriture = 'C'
|
|
AND ('20'||periode_imputation)::int >= CONCAT(SPLIT_PART(rhp('rhprovider_start'), '-', 1), SPLIT_PART(rhp('rhprovider_start'), '-', 2))::int
|
|
group by 1,2,3,4,5,6
|
|
having sum(montant) is not null),
|
|
ven_1 as (
|
|
select
|
|
imputation,
|
|
periode_imputation,
|
|
matricule,
|
|
contrat,
|
|
poste,
|
|
compte,
|
|
montant,
|
|
round(base.cti_division(montant, sum(montant) over (partition by matricule, contrat, periode_imputation, poste, compte)), 6) as ratio,
|
|
row_number() over (partition by matricule, contrat, periode_imputation, poste, compte order by montant desc) as rang
|
|
from ven_0),
|
|
ven_corr as (
|
|
select
|
|
matricule,
|
|
contrat,
|
|
periode_imputation,
|
|
poste,
|
|
compte,
|
|
1.0 - sum(ratio) as corr
|
|
from ven_1
|
|
group by 1,2,3,4,5
|
|
having sum(ratio) != 1),
|
|
ven_tot as (
|
|
select
|
|
ven_1.periode_imputation,
|
|
ven_1.matricule,
|
|
ven_1.contrat,
|
|
ven_1.poste,
|
|
ven_1.compte,
|
|
sum(ven_1.montant) as montant,
|
|
array_agg(ven_1.imputation order by ven_1.imputation) as imp,
|
|
array_agg(case when corr is not null and ven_1.rang = 1 then ven_1.ratio + ven_corr.corr else ven_1.ratio end order by ven_1.imputation) as rat,
|
|
nextval('ventilation_id') as ventilation_id
|
|
from ven_1
|
|
left join ven_corr on 1=1
|
|
and ven_corr.matricule = ven_1.matricule
|
|
and ven_corr.contrat = ven_1.contrat
|
|
and ven_corr.periode_imputation = ven_1.periode_imputation
|
|
and ven_corr.poste = ven_1.poste
|
|
and ven_corr.compte = ven_1.compte
|
|
group by 1,2,3,4,5)
|
|
select
|
|
periode_imputation,
|
|
matricule,
|
|
contrat,
|
|
poste,
|
|
compte,
|
|
sum(montant) over w as montant_tot, -- sans periode_origine.
|
|
0 = ANY(array_agg(montant) over w) as contains_zero,-- indicateur qui permet de traiter le cas des sous-périodes != imputation avec des montant_det à 0.
|
|
montant as montant_det,
|
|
imp,
|
|
rat,
|
|
ventilation_id
|
|
from ven_tot
|
|
window w as (partition by matricule, contrat, periode_imputation, poste, compte)
|
|
;
|
|
|
|
-- Récupération des différents schémas/modèles de ventilation.
|
|
TRUNCATE rh.p_ventilation
|
|
;
|
|
|
|
INSERT INTO rh.p_ventilation(oid, code, texte, plan_analytique_id)
|
|
select
|
|
ventilation_id,
|
|
ventilation_id::text,
|
|
array_to_string(imp, ',')||' @ '||array_to_string(rat, ','),
|
|
1
|
|
FROM w_ven
|
|
group by 1,2,3,4
|
|
UNION ALL
|
|
select
|
|
ventilation_id,
|
|
ventilation_id::text,
|
|
array_to_string(imp, ',')||' @ '||array_to_string(rat, ','),
|
|
1
|
|
FROM w_ven_imp
|
|
group by 1,2,3,4
|
|
UNION ALL
|
|
SELECT
|
|
0,
|
|
'N/R',
|
|
'Non renseignée',
|
|
1
|
|
;
|
|
|
|
TRUNCATE rh.p_ventilation_section
|
|
;
|
|
INSERT INTO rh.p_ventilation_section(
|
|
ventilation_id,
|
|
section_analytique_id,
|
|
section_analytique_code,
|
|
section_analytique_texte,
|
|
ratio)
|
|
SELECT
|
|
ventilation_id,
|
|
t_section_analytique.oid,
|
|
t_section_analytique.code,
|
|
t_section_analytique.texte,
|
|
rat
|
|
FROM (
|
|
SELECT
|
|
ventilation_id,
|
|
unnest(imp) as imp,
|
|
unnest(rat) as rat
|
|
FROM w_ven
|
|
group by 1,2,3) as subq
|
|
JOIN rh.t_section_analytique on t_section_analytique.code_original = imp
|
|
UNION ALL
|
|
SELECT
|
|
ventilation_id,
|
|
t_section_analytique.oid,
|
|
t_section_analytique.code,
|
|
t_section_analytique.texte,
|
|
rat
|
|
FROM (
|
|
SELECT
|
|
ventilation_id,
|
|
unnest(imp) as imp,
|
|
unnest(rat) as rat
|
|
FROM w_ven_imp
|
|
group by 1,2,3) as subq
|
|
JOIN rh.t_section_analytique on t_section_analytique.code_original = imp
|
|
UNION ALL
|
|
SELECT
|
|
0,
|
|
oid,
|
|
code,
|
|
texte,
|
|
1
|
|
FROM rh.t_section_analytique
|
|
WHERE oid = 0
|
|
;
|
|
|
|
-- VENTILATION DE LA MASSE SALARIALE.
|
|
-- OK BRUT Ventilation précise...
|
|
WITH subq AS (
|
|
select
|
|
w_historique_paie.oid,
|
|
w_ven.ventilation_id,
|
|
case when compte = '999999999' then w_historique_paie.compte_id else t_compte.oid end as compte_id -- on ne change pas le compte lorsqu'il s'agit du 999999999.
|
|
from w_historique_paie
|
|
join w_ven on 1=1
|
|
and w_ven.matricule = w_historique_paie.mat
|
|
and w_ven.contrat = w_historique_paie.relatnum
|
|
and w_ven.poste = w_historique_paie.rub
|
|
and w_ven.periode_imputation = w_historique_paie.mois_paie
|
|
and w_ven.periode_origine = substr(w_historique_paie.sous_periode, 3, 4) -- ... On prend en compte la sous_periode (date d'activité).
|
|
and w_ven.montant_det = w_historique_paie.ori_mt-- Association obligatoire en détaillé.
|
|
-- and not w_ven.contains_zero -- Ne pas prendre les ventilations qui sont égales à 0 en total pour les sous-période != imputation.
|
|
join rh.t_compte on t_compte.code_original = w_ven.compte
|
|
where rub not in (select rub from w_exc_rub))
|
|
UPDATE rh.p_historique_paie SET
|
|
ventilation_1_id = subq.ventilation_id,
|
|
compte_id = subq.compte_id,
|
|
code_original = 1
|
|
FROM subq
|
|
WHERE true
|
|
and p_historique_paie.oid = subq.oid
|
|
AND p_historique_paie.ventilation_1_id = 0
|
|
;
|
|
|
|
-- OK @BRUT Ventilation précise mais en valeur absolue (= 1ère passe)...
|
|
WITH subq AS (
|
|
select
|
|
w_historique_paie.oid,
|
|
w_ven.ventilation_id,
|
|
case when compte = '999999999' then w_historique_paie.compte_id else t_compte.oid end as compte_id -- on ne change pas le compte lorsqu'il s'agit du 999999999.
|
|
from w_historique_paie
|
|
join w_ven on 1=1
|
|
and w_ven.matricule = w_historique_paie.mat
|
|
and w_ven.contrat = w_historique_paie.relatnum
|
|
and w_ven.poste = w_historique_paie.rub
|
|
and w_ven.periode_imputation = w_historique_paie.mois_paie
|
|
and w_ven.periode_origine = substr(w_historique_paie.sous_periode, 3, 4) -- ... On prend en compte la sous_periode (date d'activité).
|
|
and @w_ven.montant_det = @w_historique_paie.ori_mt-- Association obligatoire en détaillé.
|
|
join rh.t_compte on t_compte.code_original = w_ven.compte
|
|
where rub not in (select rub from w_exc_rub))
|
|
UPDATE rh.p_historique_paie SET
|
|
ventilation_1_id = subq.ventilation_id,
|
|
compte_id = subq.compte_id,
|
|
code_original = 2
|
|
FROM subq
|
|
WHERE true
|
|
and p_historique_paie.oid = subq.oid
|
|
AND p_historique_paie.ventilation_1_id = 0
|
|
;
|
|
|
|
-- OK BRUT HP TOT Ventilation avec montant totalisé en paie en prenant en compte la sous-période...
|
|
WITH subq AS (
|
|
select
|
|
w_historique_paie.oid,
|
|
w_ven.ventilation_id,
|
|
case when compte = '999999999' then w_historique_paie.compte_id else t_compte.oid end as compte_id -- on ne change pas le compte lorsqu'il s'agit du 999999999.
|
|
from w_historique_paie
|
|
join w_ven on 1=1
|
|
and w_ven.matricule = w_historique_paie.mat
|
|
and w_ven.contrat = w_historique_paie.relatnum
|
|
and w_ven.poste = w_historique_paie.rub
|
|
and w_ven.periode_imputation = w_historique_paie.mois_paie
|
|
and w_ven.periode_origine = substr(w_historique_paie.sous_periode, 3, 4) -- ... On prend en compte la sous_periode (date d'activité).
|
|
and w_ven.montant_det = w_historique_paie.montant_total -- Association obligatoire en détaillé imputation mais totalisé.
|
|
-- and not w_ven.contains_zero -- Ne pas prendre les ventilations qui sont égales à 0 en total pour les sous-période != imputation.
|
|
join rh.t_compte on t_compte.code_original = w_ven.compte
|
|
where rub not in (select rub from w_exc_rub))
|
|
UPDATE rh.p_historique_paie SET
|
|
ventilation_1_id = subq.ventilation_id,
|
|
compte_id = subq.compte_id,
|
|
code_original = 3
|
|
FROM subq
|
|
WHERE true
|
|
and p_historique_paie.oid = subq.oid
|
|
AND p_historique_paie.ventilation_1_id = 0
|
|
;
|
|
|
|
-- OK BRUT HP TOT Ventilation avec montant totalisé @bsolue en paie en prenant en compte la sous-période...
|
|
WITH subq AS (
|
|
select
|
|
w_historique_paie.oid,
|
|
w_ven.ventilation_id,
|
|
case when compte = '999999999' then w_historique_paie.compte_id else t_compte.oid end as compte_id -- on ne change pas le compte lorsqu'il s'agit du 999999999.
|
|
from w_historique_paie
|
|
join w_ven on 1=1
|
|
and w_ven.matricule = w_historique_paie.mat
|
|
and w_ven.contrat = w_historique_paie.relatnum
|
|
and w_ven.poste = w_historique_paie.rub
|
|
and w_ven.periode_imputation = w_historique_paie.mois_paie
|
|
and w_ven.periode_origine = substr(w_historique_paie.sous_periode, 3, 4) -- ... On prend en compte la sous_periode (date d'activité).
|
|
and @w_ven.montant_det = @w_historique_paie.montant_total -- Association obligatoire en détaillé imputation mais totalisé.
|
|
-- and not w_ven.contains_zero -- Ne pas prendre les ventilations qui sont égales à 0 en total pour les sous-période != imputation.
|
|
join rh.t_compte on t_compte.code_original = w_ven.compte
|
|
where rub not in (select rub from w_exc_rub))
|
|
UPDATE rh.p_historique_paie SET
|
|
ventilation_1_id = subq.ventilation_id,
|
|
compte_id = subq.compte_id,
|
|
code_original = '3.1'
|
|
FROM subq
|
|
WHERE true
|
|
and p_historique_paie.oid = subq.oid
|
|
AND p_historique_paie.ventilation_1_id = 0
|
|
;
|
|
|
|
-- OK BRUT Ventilation lorsque pas les mêmes montant sous-période entre paie et a01_compta (totaux égaux)...
|
|
WITH subq AS (
|
|
select
|
|
w_historique_paie.oid,
|
|
w_ven.ventilation_id,
|
|
montant_total != montant_total_imputation as contains_retro, -- permet de cibler uniquement les rubriques avec de la rétro.
|
|
case when compte = '999999999' then w_historique_paie.compte_id else t_compte.oid end as compte_id -- on ne change pas le compte lorsqu'il s'agit du 999999999.
|
|
from w_historique_paie
|
|
join w_ven on 1=1
|
|
and w_ven.matricule = w_historique_paie.mat
|
|
and w_ven.contrat = w_historique_paie.relatnum
|
|
and w_ven.poste = w_historique_paie.rub
|
|
and w_ven.periode_imputation = w_historique_paie.mois_paie
|
|
and w_ven.periode_origine = substr(w_historique_paie.sous_periode, 3, 4) -- ... On prend en compte la sous_periode (date d'activité).
|
|
--and w_ven.montant_det = w_historique_paie.ori_mt-- non.
|
|
-- and not w_ven.contains_zero -- Ne pas prendre les ventilations qui sont égales à 0 en total pour les sous-période != imputation.
|
|
join rh.t_compte on t_compte.code_original = w_ven.compte
|
|
where rub not in (select rub from w_exc_rub))
|
|
UPDATE rh.p_historique_paie SET
|
|
ventilation_1_id = subq.ventilation_id,
|
|
compte_id = subq.compte_id,
|
|
code_original = 4
|
|
FROM subq
|
|
WHERE true
|
|
and p_historique_paie.oid = subq.oid
|
|
and subq.contains_retro
|
|
AND p_historique_paie.ventilation_1_id = 0
|
|
;
|
|
|
|
-- COT ventilation sans sous-période avec montant (totalisé à l'imputation)...
|
|
WITH subq AS (
|
|
select
|
|
w_historique_paie.oid,
|
|
w_ven_imp.ventilation_id,
|
|
case when compte = '999999999' then w_historique_paie.compte_id else t_compte.oid end as compte_id -- on ne change pas le compte lorsqu'il s'agit du 999999999.
|
|
from w_historique_paie
|
|
join w_ven_imp on 1=1
|
|
and w_ven_imp.matricule = w_historique_paie.mat
|
|
and w_ven_imp.contrat = w_historique_paie.relatnum
|
|
and w_ven_imp.poste = w_historique_paie.rub
|
|
and w_ven_imp.periode_imputation = w_historique_paie.mois_paie
|
|
-- and w_ven_imp.periode_origine = substr(w_historique_paie.sous_periode, 3, 4) -- ... On prend en compte la sous_periode (date d'activité).
|
|
and w_ven_imp.montant_tot = w_historique_paie.montant_total_imputation -- Association obligatoire en total imputation.
|
|
join rh.t_compte on t_compte.code_original = w_ven_imp.compte
|
|
where rub not in (select rub from w_exc_rub))
|
|
UPDATE rh.p_historique_paie SET
|
|
ventilation_1_id = subq.ventilation_id,
|
|
compte_id = subq.compte_id,
|
|
code_original = 5
|
|
FROM subq
|
|
WHERE true
|
|
and p_historique_paie.oid = subq.oid
|
|
AND p_historique_paie.ventilation_1_id = 0
|
|
;
|
|
|
|
-- OK AST Ventilation des astreintes
|
|
WITH subq AS (
|
|
select
|
|
w_historique_paie.oid,
|
|
w_ven.ventilation_id,
|
|
t_compte.oid as compte_id
|
|
from w_historique_paie
|
|
join (select to_id from rh.t_listes join rh.t_listes_contenu on t_listes_contenu.liste_id = t_listes.oid where code = 'RUB_AST_9956') as subq ON subq.to_id = w_historique_paie.rubrique_id
|
|
join w_ven on 1=1
|
|
and w_ven.matricule = w_historique_paie.mat
|
|
and w_ven.contrat = w_historique_paie.relatnum
|
|
and w_ven.periode_imputation = w_historique_paie.mois_paie
|
|
and w_ven.poste = '9956'
|
|
join rh.t_compte on t_compte.code_original = w_ven.compte
|
|
where rub not in (select rub from w_exc_rub))
|
|
UPDATE rh.p_historique_paie SET
|
|
ventilation_1_id = subq.ventilation_id,
|
|
compte_id = subq.compte_id,
|
|
code_original = 6
|
|
FROM subq
|
|
WHERE true
|
|
and p_historique_paie.oid = subq.oid
|
|
AND p_historique_paie.ventilation_1_id = 0
|
|
;
|
|
|
|
-- VENTILATION DES ETPS.
|
|
-- OK Ventilation précise...
|
|
WITH subq AS (
|
|
select
|
|
w_historique_paie.oid,
|
|
w_ven.ventilation_id,
|
|
case when compte = '999999999' then w_historique_paie.compte_id else t_compte.oid end as compte_id -- on ne change pas le compte lorsqu'il s'agit du 999999999.
|
|
from w_historique_paie
|
|
join w_ven on 1=1
|
|
and w_ven.matricule = w_historique_paie.mat
|
|
and w_ven.contrat = w_historique_paie.relatnum
|
|
and w_ven.poste = w_historique_paie.rub
|
|
and w_ven.periode_imputation = w_historique_paie.mois_paie
|
|
and w_ven.periode_origine = substr(w_historique_paie.sous_periode, 3, 4) -- ... On prend en compte la sous_periode (date d'activité).
|
|
and w_ven.montant_det = w_historique_paie.base -- Association obligatoire en détaillé.
|
|
-- and not w_ven.contains_zero -- Ne pas prendre les ventilations qui sont égales à 0 en total pour les sous-période != imputation.
|
|
join rh.t_compte on t_compte.code_original = w_ven.compte
|
|
where rub not in (select rub from w_exc_rub))
|
|
UPDATE rh.p_historique_paie SET
|
|
ventilation_1_id = subq.ventilation_id,
|
|
compte_id = subq.compte_id,
|
|
code_original = 7
|
|
FROM subq
|
|
WHERE true
|
|
and p_historique_paie.oid = subq.oid
|
|
AND p_historique_paie.ventilation_1_id = 0
|
|
;
|
|
|
|
-- ETP @BSOLUE.
|
|
WITH subq AS (
|
|
select
|
|
w_historique_paie.oid,
|
|
w_ven.ventilation_id,
|
|
case when compte = '999999999' then w_historique_paie.compte_id else t_compte.oid end as compte_id -- on ne change pas le compte lorsqu'il s'agit du 999999999.
|
|
from w_historique_paie
|
|
join w_ven on 1=1
|
|
and w_ven.matricule = w_historique_paie.mat
|
|
and w_ven.contrat = w_historique_paie.relatnum
|
|
and w_ven.poste = w_historique_paie.rub
|
|
and w_ven.periode_imputation = w_historique_paie.mois_paie
|
|
and w_ven.periode_origine = substr(w_historique_paie.sous_periode, 3, 4) -- ... On prend en compte la sous_periode (date d'activité).
|
|
and @w_ven.montant_det = @w_historique_paie.base -- Association obligatoire en détaillé.
|
|
-- and not w_ven.contains_zero -- Ne pas prendre les ventilations qui sont égales à 0 en total pour les sous-période != imputation.
|
|
join rh.t_compte on t_compte.code_original = w_ven.compte
|
|
where rub not in (select rub from w_exc_rub))
|
|
UPDATE rh.p_historique_paie SET
|
|
ventilation_1_id = subq.ventilation_id,
|
|
compte_id = subq.compte_id,
|
|
code_original = 8
|
|
FROM subq
|
|
WHERE true
|
|
and p_historique_paie.oid = subq.oid
|
|
AND p_historique_paie.ventilation_1_id = 0
|
|
;
|
|
|
|
-- OK Ventilation avec base totalisé en paie en prenant en compte la sous-période...
|
|
WITH subq AS (
|
|
select
|
|
w_historique_paie.oid,
|
|
w_ven.ventilation_id,
|
|
case when compte = '999999999' then w_historique_paie.compte_id else t_compte.oid end as compte_id -- on ne change pas le compte lorsqu'il s'agit du 999999999.
|
|
from w_historique_paie
|
|
join w_ven on 1=1
|
|
and w_ven.matricule = w_historique_paie.mat
|
|
and w_ven.contrat = w_historique_paie.relatnum
|
|
and w_ven.poste = w_historique_paie.rub
|
|
and w_ven.periode_imputation = w_historique_paie.mois_paie
|
|
and w_ven.periode_origine = substr(w_historique_paie.sous_periode, 3, 4) -- ... On prend en compte la sous_periode (date d'activité).
|
|
and w_ven.montant_det = w_historique_paie.base_total -- Association obligatoire en détaillé imputation mais totalisé.
|
|
-- and not w_ven.contains_zero -- NON car en total. Ne pas prendre les ventilations qui sont égales à 0 en total pour les sous-période != imputation.
|
|
join rh.t_compte on t_compte.code_original = w_ven.compte
|
|
where rub not in (select rub from w_exc_rub))
|
|
UPDATE rh.p_historique_paie SET
|
|
ventilation_1_id = subq.ventilation_id,
|
|
compte_id = subq.compte_id,
|
|
code_original = 9
|
|
FROM subq
|
|
WHERE true
|
|
and p_historique_paie.oid = subq.oid
|
|
AND p_historique_paie.ventilation_1_id = 0
|
|
;
|
|
|
|
SELECT base.cti_stash_pop_table_constraints('rh.p_historique_paie')
|
|
;
|
|
|
|
SELECT base.cti_stash_pop_table_indexes('rh.p_historique_paie')
|
|
;
|
|
|
|
]]></sqlcmd>
|
|
</NODE>
|
|
<NODE label="Arrêts de travail">
|
|
<sqlcmd><![CDATA[
|
|
|
|
-- A mettre dans t_divers (IMP_INC_MAR) :
|
|
-- ADP, AT1, AT3, AT5, ATN, D3_, D4_, D5_, DIV, EF1, EF2, EF3, ENF, FO1, FO2, MA1, MA2, MA3, MA4, MA5, MA6, MAN, MAP, MAT, PAP, PAT, POS, RA1, RA3, RA5, RAN, SY1, SY2, SY3
|
|
|
|
-- Création d'une table temporaire
|
|
DROP TABLE IF EXISTS w_arrets_0
|
|
;
|
|
|
|
CREATE TEMP TABLE w_arrets_0 AS
|
|
select
|
|
abs.oid as uid,
|
|
to_char(abs.begin_date, 'YYYYMM')::numeric AS mois,
|
|
abs.begin_date::date as date_debut,
|
|
abs.end_date::date as date_fin,
|
|
abs.nbjrcalen as nb_jours,
|
|
abs.xnbheures as nb_heures,
|
|
ta_motifevt.motif,
|
|
salarie.matricule as mat
|
|
from prod_pleiades2.contrat
|
|
join prod_pleiades2.relationcontrat on relationcontrat.oid = contrat.ctrrelation
|
|
join prod_pleiades2.salarie on salarie.oid = relationcontrat.relatmatricule
|
|
join prod_pleiades2.priseabsence as abs on abs.refctr = contrat.oid
|
|
join prod_pleiades2.ta_motifevt on ta_motifevt.oid = abs.motifevt
|
|
where 1=1
|
|
and case when (SELECT length(trim(valeur)) > 0 FROM rh.t_divers WHERE code = 'IMP_INC_MAR') then ta_motifevt.motif IN (SELECT trim(unnest(string_to_array(valeur, ','))) FROM rh.t_divers WHERE code = 'IMP_INC_MAR') else true end
|
|
and ta_motifevt.motif NOT IN (SELECT trim(unnest(string_to_array(valeur, ','))) FROM rh.t_divers WHERE code = 'IMP_EXC_MAR')
|
|
group by 1,2,3,4,5,6,7,8
|
|
;
|
|
|
|
DROP TABLE IF EXISTS w_arrets_mois -- version retravaillée (aggrégation des arrêts de même type continus sur un même mois).
|
|
;
|
|
|
|
CREATE TEMP TABLE w_arrets_mois AS
|
|
with clustering as (
|
|
select
|
|
*,
|
|
case when lag(date_fin) over (partition by mat, motif order by date_debut) = date_debut - '1 day'::interval then null else true end as new_cluster
|
|
from w_arrets_0
|
|
order by mat, motif, date_debut),
|
|
assigned_clustering as (
|
|
select
|
|
*,
|
|
mat||'-'||count(new_cluster) over (order by mat, motif, date_debut) as cluster_id
|
|
from clustering
|
|
)
|
|
select
|
|
mat as matricule,
|
|
motif,
|
|
cluster_id,
|
|
array_agg(uid) as uid, -- uid d'origine potentiellement dédoublé (inutilisable).
|
|
mat||'-'||row_number() over (order by mois) as uid2, -- uid ventilé.
|
|
min(date_debut) as date_debut,
|
|
max(date_fin) as date_fin,
|
|
mois as mois,
|
|
sum(nb_jours) as nb_jours,
|
|
sum(nb_heures) as nb_heures
|
|
from assigned_clustering
|
|
group by mat, motif, cluster_id, mois
|
|
;
|
|
|
|
DROP TABLE IF EXISTS w_arrets_mois_1 -- ventilation retravaillée + id de contrats.
|
|
;
|
|
|
|
CREATE TEMP TABLE w_arrets_mois_1 AS
|
|
select
|
|
w_arrets_mois.*,
|
|
p_salaries.oid as salarie_id,
|
|
p_contrats_mois.contrat_id,
|
|
p_contrats_mois.oid as contrat_mois_id
|
|
from w_arrets_mois
|
|
join rh.p_salaries on p_salaries.matricule = w_arrets_mois.matricule
|
|
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_arrets_mois.date_debut, w_arrets_mois.date_fin)
|
|
;
|
|
|
|
-- Agrégation des arrêts de travail.
|
|
DROP TABLE IF EXISTS w_arrets
|
|
;
|
|
|
|
CREATE TEMP TABLE w_arrets AS
|
|
select
|
|
matricule,
|
|
motif,
|
|
cluster_id,
|
|
matricule||'-'||motif||'-'||cluster_id as uid3, -- un uid3 par arrêt
|
|
--array_agg(uid) as uid,
|
|
array_agg(uid2) as uid2, -- plusieurs uid2 par uid3
|
|
min(date_debut) as date_debut,
|
|
max(date_fin) as date_fin,
|
|
max(mois) as mois,
|
|
sum(nb_jours) as nb_jours,
|
|
sum(nb_heures) as nb_heures
|
|
from w_arrets_mois
|
|
group by matricule, motif, cluster_id
|
|
;
|
|
|
|
-- Alimentation des arrêts de travail
|
|
TRUNCATE rh.p_arrets_travail
|
|
;
|
|
|
|
ALTER SEQUENCE rh.s_arrets_travail RESTART WITH 1
|
|
;
|
|
|
|
DROP TABLE IF EXISTS w_arrets_travail
|
|
;
|
|
|
|
CREATE TEMP TABLE w_arrets_travail AS
|
|
SELECT p_salaries.oid as salarie_id,
|
|
(max(ARRAY[extract(EPOCH from p_contrats.date_fin), p_contrats.oid]))[2] as contrat_id,
|
|
w_arrets.mois as mois_activite,
|
|
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,
|
|
coalesce(t_motifs_arret.oid, 0) AS motif_arret_id,
|
|
0 AS precision_motif_arret_id,
|
|
w_arrets.nb_jours,
|
|
w_arrets.nb_heures,
|
|
w_arrets.cluster_id,
|
|
w_arrets.uid2,
|
|
w_arrets.uid3,
|
|
nextval('rh.s_arrets_travail'::regclass) as oid
|
|
FROM w_arrets
|
|
JOIN rh.p_salaries ON p_salaries.matricule = w_arrets.matricule
|
|
LEFT JOIN rh.t_motifs_arret ON t_motifs_arret.code_original = w_arrets.motif
|
|
JOIN rh.p_contrats ON 1=1 -- Ne pas s'inquièter si cetains arrets ne sont pas remontés faute d'association avec un contrat car il doit OBLIGRATOIREMENT avoir un contrat associé dans PLEIADES.
|
|
and p_contrats.salarie_id = p_salaries.oid
|
|
and base.cti_overlaps(p_contrats.date_debut, p_contrats.date_fin, w_arrets.date_debut, w_arrets.date_fin)
|
|
GROUP BY 1,3,4,5,6,7,8,9,10,11,12,13
|
|
;
|
|
|
|
INSERT INTO rh.p_arrets_travail(
|
|
oid,
|
|
salarie_id,
|
|
contrat_id,
|
|
mois_activite,
|
|
date_debut,
|
|
date_fin,
|
|
date_reprise,
|
|
motif_arret_id,
|
|
precision_motif_arret_id,
|
|
nb_jours,
|
|
nb_heures
|
|
)
|
|
select
|
|
oid,
|
|
salarie_id,
|
|
contrat_id,
|
|
mois_activite,
|
|
date_debut,
|
|
date_fin,
|
|
date_reprise,
|
|
motif_arret_id,
|
|
precision_motif_arret_id,
|
|
nb_jours,
|
|
nb_heures
|
|
from w_arrets_travail
|
|
;
|
|
|
|
-- 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_heures,
|
|
nb_arret
|
|
)
|
|
SELECT
|
|
subq.oid AS arret_travail_id,
|
|
w_arrets_mois_1.salarie_id AS salarie_id,
|
|
w_arrets_mois_1.contrat_id AS contrat_id,
|
|
w_arrets_mois_1.contrat_mois_id AS contrat_mois_id,
|
|
p_contrats_mois.mois_activite,
|
|
CASE WHEN w_arrets_mois_1.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 w_arrets_mois_1.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,
|
|
w_arrets_mois_1.date_debut,
|
|
w_arrets_mois_1.date_fin,
|
|
nb_jours,
|
|
nb_heures,
|
|
1
|
|
FROM (select
|
|
unnest(uid2) as uid2,
|
|
salarie_id,
|
|
contrat_id,
|
|
cluster_id,
|
|
oid
|
|
from w_arrets_travail) as subq
|
|
join w_arrets_mois_1 on w_arrets_mois_1.uid2 = subq.uid2
|
|
join rh.p_contrats_mois on p_contrats_mois.oid = w_arrets_mois_1.contrat_mois_id
|
|
group by 1,2,3,4,5,8,9,10,11,12,13,w_arrets_mois_1.date_debut,w_arrets_mois_1.date_fin
|
|
;
|
|
|
|
-- Calcul de l'indicateur 'nb reprise après arrêt'.
|
|
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 label="Mise à jour des libellés et classes (FICOM et Codes emploi comptables)">
|
|
<sqlcmd><![CDATA[
|
|
|
|
-- Chargement des données CSV CEC.
|
|
drop table if EXISTS w_cec
|
|
;
|
|
|
|
create temp table w_cec as
|
|
select
|
|
''::text as code,
|
|
''::text as texte
|
|
limit 0
|
|
;
|
|
|
|
copy w_cec from 'D:/CTI/iCTI_377/modules/rh/sjsl-data/codes_emploi_comptables.csv' CSV delimiter '|'
|
|
;
|
|
|
|
-- Chargement des données CSV FICOM.
|
|
drop table if EXISTS w_ficom
|
|
;
|
|
|
|
create temp table w_ficom as
|
|
select
|
|
''::text as cdr_code,
|
|
''::text as cdr_texte,
|
|
''::text as spe_code,
|
|
''::text as spe_texte,
|
|
''::text as ssp_code,
|
|
''::text as ssp_texte,
|
|
''::text as uf_code,
|
|
''::text as uf_texte
|
|
limit 0
|
|
;
|
|
|
|
copy w_ficom from 'D:/CTI/iCTI_377/modules/rh/sjsl-data/ficom.csv' CSV delimiter ';'
|
|
;
|
|
|
|
-- Màj des libellés d'UF principales.
|
|
update rh.t_services
|
|
set texte = w_ficom.uf_texte,
|
|
texte_court = substr(w_ficom.uf_texte, 1, 50)
|
|
from w_ficom
|
|
where w_ficom.uf_code = code_original
|
|
;
|
|
|
|
-- Màj des libellés de CEC principaux.
|
|
update rh.t_sections_analytiques
|
|
set texte = w_cec.texte,
|
|
texte_court = substr(w_cec.texte, 1, 50)
|
|
from w_cec
|
|
where w_cec.code = code_original
|
|
;
|
|
|
|
-- Suppression des 5 classes si elles existent.
|
|
delete from rh.t_classes_sections_elements
|
|
where section_id in (
|
|
select s.oid from rh.t_classes as c
|
|
join rh.t_classes_sections as s on s.classe_id = c.oid
|
|
where c.code IN ('ANAUFS', 'ANACDR', 'ANASPE', 'ANASSP', 'ANACEC'))
|
|
;
|
|
|
|
-- Alimentation des classes.
|
|
-- Classe d'UF (liée aux ventilations).
|
|
INSERT INTO rh.t_classes_sections(code, texte, classe_id)
|
|
select
|
|
substr(section_analytique_code, 1, 4),
|
|
coalesce(w_ficom.uf_texte, substr(section_analytique_code, 1, 4)),
|
|
(select oid from rh.t_classes where code = 'ANAUFS')
|
|
from rh.p_ventilation_section
|
|
left join rh.t_classes_sections on 1=1
|
|
and t_classes_sections.classe_id = (select oid from rh.t_classes where code = 'ANAUFS')
|
|
and t_classes_sections.code = substr(section_analytique_code, 1, 4)
|
|
LEFT JOIN w_ficom on w_ficom.uf_code = substr(section_analytique_code, 1, 4)
|
|
where 1=1
|
|
and t_classes_sections.code is null
|
|
and ventilation_id != 0
|
|
group by 1,2,3
|
|
;
|
|
|
|
INSERT INTO rh.t_classes_sections_elements (section_id, to_id)
|
|
SELECT
|
|
t_classes_sections.oid AS section_id,
|
|
section_analytique_id AS to_id
|
|
FROM rh.t_classes
|
|
join rh.t_classes_sections on t_classes_sections.classe_id = t_classes.oid
|
|
join rh.p_ventilation_section on substr(p_ventilation_section.section_analytique_code, 1, 4) = t_classes_sections.code
|
|
WHERE t_classes.code = 'ANAUFS'
|
|
group by 1,2
|
|
;
|
|
|
|
-- Classe CDR (tiré uniquement du FICOM).
|
|
INSERT INTO rh.t_classes_sections(code, texte, classe_id)
|
|
select
|
|
cdr_code,
|
|
cdr_texte,
|
|
(select oid from rh.t_classes where code = 'ANACDR')
|
|
from w_ficom
|
|
left join rh.t_classes_sections on 1=1
|
|
and t_classes_sections.classe_id = (select oid from rh.t_classes where code = 'ANACDR')
|
|
and t_classes_sections.code = cdr_code
|
|
where t_classes_sections.code is null
|
|
group by 1,2,3
|
|
;
|
|
|
|
INSERT INTO rh.t_classes_sections_elements (section_id, to_id)
|
|
SELECT
|
|
t_classes_sections.oid AS section_id,
|
|
section_analytique_id AS to_id
|
|
FROM rh.t_classes
|
|
join rh.t_classes_sections on t_classes_sections.classe_id = t_classes.oid
|
|
join w_ficom on w_ficom.cdr_code = t_classes_sections.code
|
|
join rh.p_ventilation_section on substr(p_ventilation_section.section_analytique_code, 1, 4) = w_ficom.uf_code
|
|
WHERE t_classes.code = 'ANACDR'
|
|
group by 1,2
|
|
;
|
|
|
|
-- Classe Spé
|
|
INSERT INTO rh.t_classes_sections(code, texte, classe_id)
|
|
select
|
|
spe_code,
|
|
spe_texte,
|
|
(select oid from rh.t_classes where code = 'ANASPE')
|
|
from w_ficom
|
|
left join rh.t_classes_sections on 1=1
|
|
and t_classes_sections.classe_id = (select oid from rh.t_classes where code = 'ANASPE')
|
|
and t_classes_sections.code = spe_code
|
|
where t_classes_sections.code is null
|
|
group by 1,2,3
|
|
;
|
|
|
|
INSERT INTO rh.t_classes_sections_elements (section_id, to_id)
|
|
SELECT
|
|
t_classes_sections.oid AS section_id,
|
|
section_analytique_id AS to_id
|
|
FROM rh.t_classes
|
|
join rh.t_classes_sections on t_classes_sections.classe_id = t_classes.oid
|
|
join w_ficom on w_ficom.spe_code = t_classes_sections.code
|
|
join rh.p_ventilation_section on substr(p_ventilation_section.section_analytique_code, 1, 4) = w_ficom.uf_code
|
|
WHERE t_classes.code = 'ANASPE'
|
|
group by 1,2
|
|
;
|
|
|
|
-- Classe Sous-Spé
|
|
INSERT INTO rh.t_classes_sections(code, texte, classe_id)
|
|
select
|
|
ssp_code,
|
|
ssp_texte,
|
|
(select oid from rh.t_classes where code = 'ANASSP')
|
|
from w_ficom
|
|
left join rh.t_classes_sections on 1=1
|
|
and t_classes_sections.classe_id = (select oid from rh.t_classes where code = 'ANASSP')
|
|
and t_classes_sections.code = ssp_code
|
|
where t_classes_sections.code is null
|
|
group by 1,2,3
|
|
;
|
|
|
|
INSERT INTO rh.t_classes_sections_elements (section_id, to_id)
|
|
SELECT
|
|
t_classes_sections.oid AS section_id,
|
|
section_analytique_id AS to_id
|
|
FROM rh.t_classes
|
|
join rh.t_classes_sections on t_classes_sections.classe_id = t_classes.oid
|
|
join w_ficom on w_ficom.ssp_code = t_classes_sections.code
|
|
join rh.p_ventilation_section on substr(p_ventilation_section.section_analytique_code, 1, 4) = w_ficom.uf_code
|
|
WHERE t_classes.code = 'ANASSP'
|
|
group by 1,2
|
|
;
|
|
|
|
-- Classe de CEC.
|
|
INSERT INTO rh.t_classes_sections(code, texte, classe_id)
|
|
select
|
|
substr(section_analytique_code, 7, 4),
|
|
coalesce(w_cec.texte, substr(section_analytique_code, 7, 4)),
|
|
(select oid from rh.t_classes where code = 'ANACEC')
|
|
from rh.p_ventilation_section
|
|
left join rh.t_classes_sections on 1=1
|
|
and t_classes_sections.classe_id = (select oid from rh.t_classes where code = 'ANACEC')
|
|
and t_classes_sections.code = substr(section_analytique_code, 7, 4)
|
|
LEFT JOIN w_cec on w_cec.code = substr(section_analytique_code, 7, 4)
|
|
where 1=1
|
|
and t_classes_sections.code is null
|
|
and ventilation_id != 0
|
|
group by 1,2,3
|
|
;
|
|
|
|
INSERT INTO rh.t_classes_sections_elements (section_id, to_id)
|
|
SELECT
|
|
t_classes_sections.oid AS section_id,
|
|
section_analytique_id AS to_id
|
|
FROM rh.t_classes
|
|
join rh.t_classes_sections on t_classes_sections.classe_id = t_classes.oid
|
|
join rh.p_ventilation_section on substr(p_ventilation_section.section_analytique_code, 7, 4) = t_classes_sections.code
|
|
WHERE t_classes.code = 'ANACEC'
|
|
group by 1,2
|
|
;
|
|
|
|
]]></sqlcmd>
|
|
</NODE>
|
|
</NODE>
|
|
<NODE name="POST" label="POST-TRAITEMENTS">
|
|
<NODE name="DIVERS" type="common"/>
|
|
<NODE label="Mise à jour de la table Divers (mois en cours)">
|
|
<sqlcmd><![CDATA[
|
|
|
|
-- Màj du mois non clôturé.
|
|
DELETE FROM rh.t_divers
|
|
WHERE code = 'MOIS_EN_COURS'
|
|
;
|
|
|
|
]]></sqlcmd>
|
|
</NODE>
|
|
<NODE name="POST" type="common"/>
|
|
</NODE>
|
|
<NODE name="VACUUM" label="REORGANISATION BASE DE DONNEES">
|
|
<NODE name="VACUUM" type="common" />
|
|
</NODE>
|
|
<NODE name="RAZ" label="RAZ BASE">
|
|
<NODE name="RAZ" type="common" />
|
|
</NODE>
|
|
<NODE name="RAZ_ALL" label="RAZ ALL">
|
|
<NODE name="RAZ_ALL" type="common" />
|
|
</NODE>
|
|
</ROOT>
|