<?xml version="1.0" encoding="ISO-8859-15"?>
|
|
<ROOT>
|
|
<NODE name="INIT" label="SPECIFIQUE PEGASE">
|
|
<NODE label="Identification des entreprises/établissements">
|
|
<sqlcmd><![CDATA[
|
|
|
|
/***********
|
|
* PART 1/2 PRESTATAIRE (prod_pegase ?> temp.x_) *
|
|
************/
|
|
|
|
-- Création d'une table temp des établissements pour faciliter les futures jointures.
|
|
DROP TABLE IF EXISTS w_ets
|
|
;
|
|
|
|
CREATE TEMP TABLE w_ets AS
|
|
SELECT
|
|
societe.idsociete,
|
|
societe.codsociete,
|
|
etablissements.codetab,
|
|
MAX(numsiren) as siren,
|
|
MAX(numsiren||nic) as siret,
|
|
MAX(nomsociete) as nomsociete,
|
|
MAX(nometab) as nometab
|
|
FROM prod_pegase.etablissements
|
|
JOIN prod_pegase.societe ON societe.idsociete = etablissements.idsociete
|
|
WHERE 1=1
|
|
and nullif(trim(etablissements.codetab), '') is not null
|
|
and (1!=1
|
|
OR numsiren IN (SELECT rhp_in('siren')) -- Soit un ou plusieurs SIREN ont été défini,
|
|
OR numsiren||nic IN (SELECT rhp_in('siren')) -- et/ou soit un ou plusieurs SIRET,
|
|
OR societe.codsociete IN (SELECT rhp_in('siren')) -- et/ou soit un ou plusieurs codes entreprise.
|
|
OR etablissements.codetab IN (SELECT rhp_in('siren'))) -- et/ou soit un ou plusieurs codes établissement.
|
|
GROUP BY 1,2,3
|
|
;
|
|
|
|
-- Identification des Entreprises.
|
|
DROP TABLE IF EXISTS temp.x_ref_ent
|
|
;
|
|
|
|
CREATE TABLE temp.x_ref_ent AS
|
|
SELECT
|
|
idsociete as code_original,
|
|
codsociete as code,
|
|
MAX(nomsociete) as texte,
|
|
MAX(siren) as siren,
|
|
null::text as texte_court
|
|
FROM w_ets
|
|
GROUP BY 1,2
|
|
;
|
|
|
|
-- Identification des Etablissements.
|
|
DROP TABLE IF EXISTS temp.x_ref_ets
|
|
;
|
|
|
|
CREATE TABLE temp.x_ref_ets AS
|
|
SELECT
|
|
idsociete as ent_code_original,
|
|
idsociete||'-'||codetab as ety_code_original,
|
|
codetab as code_original,
|
|
codetab as code,
|
|
MAX(siret) as siret,
|
|
MAX(nometab) as texte,
|
|
null::text as texte_court
|
|
FROM w_ets
|
|
GROUP BY 1,2,3,4
|
|
;
|
|
|
|
]]></sqlcmd>
|
|
</NODE>
|
|
<NODE label="Identification des informations permanentes">
|
|
<sqlcmd><![CDATA[
|
|
|
|
-- Identification des Catégories Socio-Professionnelles.
|
|
DROP TABLE IF EXISTS temp.x_ref_categorie_socio_professionnelle
|
|
;
|
|
|
|
CREATE TABLE temp.x_ref_categorie_socio_professionnelle AS
|
|
SELECT
|
|
lower(codemploi2003) as code_original,
|
|
lower(codemploi2003) as code,
|
|
max(libelleemploi) as texte,
|
|
null::text as texte_court
|
|
FROM prod_pegase.emploisinsee2003
|
|
GROUP BY 1,2
|
|
;
|
|
|
|
-- Identification des Nationalités.
|
|
DROP TABLE IF EXISTS temp.x_ref_nationalite
|
|
;
|
|
|
|
CREATE TABLE temp.x_ref_nationalite AS
|
|
SELECT
|
|
astocker as code_original,
|
|
astocker as code,
|
|
aafficher as texte,
|
|
null::text as texte_court
|
|
FROM prod_pegase.valeurschamps
|
|
WHERE codliste = 'TYPNATIONALITE1'
|
|
GROUP BY 1,2,3
|
|
;
|
|
|
|
-- Identification des motifs de début de contrat.
|
|
DROP TABLE IF EXISTS temp.x_ref_motif_debut_contrat
|
|
;
|
|
|
|
CREATE TABLE temp.x_ref_motif_debut_contrat AS
|
|
SELECT
|
|
astocker as code_original,
|
|
astocker as code,
|
|
aafficher as texte,
|
|
null::text as texte_court
|
|
FROM prod_pegase.valeurschamps
|
|
WHERE codliste = 'DADSUMOTIFDEBPER'
|
|
GROUP BY 1,2,3,4
|
|
;
|
|
|
|
-- Identification des motifs de fin de contrat.
|
|
DROP TABLE IF EXISTS temp.x_ref_motif_fin_contrat
|
|
;
|
|
|
|
CREATE TABLE temp.x_ref_motif_fin_contrat AS
|
|
SELECT
|
|
astocker as code_original,
|
|
astocker as code,
|
|
aafficher as texte,
|
|
null::text as texte_court
|
|
FROM prod_pegase.valeurschamps
|
|
WHERE codliste = 'DADSUMOTIFFINPER'
|
|
GROUP BY 1,2,3,4
|
|
;
|
|
|
|
-- Identification des types de contrat.
|
|
DROP TABLE IF EXISTS temp.x_ref_type_contrat
|
|
;
|
|
|
|
CREATE TABLE temp.x_ref_type_contrat AS
|
|
SELECT
|
|
astocker as code_original,
|
|
astocker as code,
|
|
aafficher as texte,
|
|
null::text as texte_court
|
|
FROM prod_pegase.valeurschamps
|
|
WHERE codliste = 'EF_TYPCONTRAT'
|
|
GROUP BY 1,2,3,4
|
|
;
|
|
|
|
-- Identification des groupes cotisants.
|
|
DROP TABLE IF EXISTS temp.x_ref_groupe_cotisant
|
|
;
|
|
|
|
CREATE TABLE temp.x_ref_groupe_cotisant AS
|
|
SELECT
|
|
identif as code_original,
|
|
codgrpcotis as code,
|
|
max(libellegrpcotis) as texte,
|
|
null::text as texte_court
|
|
FROM prod_pegase.groupescotisants
|
|
GROUP BY 1,2
|
|
;
|
|
|
|
-- Identification des organismes de cotisation
|
|
DROP TABLE IF EXISTS temp.x_ref_organisme_cotisation
|
|
;
|
|
|
|
CREATE TABLE temp.x_ref_organisme_cotisation AS
|
|
SELECT
|
|
identif as code_original,
|
|
codorganisme as code,
|
|
nom as texte,
|
|
null::text as texte_court
|
|
FROM prod_pegase.organismes
|
|
GROUP BY 1,2,3,4
|
|
;
|
|
|
|
-- Identification des qualifications
|
|
DROP TABLE IF EXISTS temp.x_ref_qualification
|
|
;
|
|
|
|
CREATE TABLE temp.x_ref_qualification AS
|
|
SELECT
|
|
substr(md5(emploi), 1, 5) as code_original,
|
|
substr(md5(emploi), 1, 5) as code,
|
|
emploi as texte,
|
|
null::text as texte_court
|
|
FROM prod_pegase.salaries
|
|
GROUP BY 1,2,3,4
|
|
;
|
|
|
|
-- Identification des Comptes
|
|
|
|
-- Identification des situations de famille
|
|
DROP TABLE IF EXISTS temp.x_ref_situation_famille
|
|
;
|
|
|
|
CREATE TABLE temp.x_ref_situation_famille AS
|
|
SELECT
|
|
astocker as code_original,
|
|
astocker as code,
|
|
aafficher as texte,
|
|
null::text as texte_court
|
|
FROM prod_pegase.valeurschamps
|
|
WHERE codliste = 'TYPSITFAM'
|
|
GROUP BY 1,2,3,4
|
|
;
|
|
|
|
-- Identification des statuts
|
|
DROP TABLE IF EXISTS temp.x_ref_statut
|
|
;
|
|
|
|
CREATE TABLE temp.x_ref_statut AS
|
|
SELECT
|
|
codlib as code_original,
|
|
codlib as code,
|
|
nomlibelle as texte,
|
|
null::text as texte_court
|
|
FROM prod_pegase.libellesdivers
|
|
WHERE typlib = '2'
|
|
GROUP BY 1,2,3,4
|
|
;
|
|
|
|
-- Identification des types de temps de travail
|
|
DROP TABLE IF EXISTS temp.x_ref_type_temps_travail
|
|
;
|
|
|
|
CREATE TABLE temp.x_ref_type_temps_travail AS
|
|
with ttt as (
|
|
select
|
|
typtravail::text || '-'::text || case when typtravail = 1 then '10000'::text else lpad(coalesce(nullif(dadsusaltauxtppartiel, 0)::text, '10000'::text), 5, '0') end as code,
|
|
aafficher ||
|
|
case
|
|
when typtravail = 1 then ''::text
|
|
else ' ('::text || round(case when typtravail = 1 then 100.0 else coalesce(nullif(dadsusaltauxtppartiel / 100.0, 0), 100.0) end, 2) || '%)'::text
|
|
end as texte
|
|
from prod_pegase.salaries
|
|
join prod_pegase.valeurschamps on 1=1
|
|
and codliste = 'TYPTRAVAIL'
|
|
and valeurschamps.astocker = salaries.typtravail
|
|
group by 1,2)
|
|
SELECT
|
|
code as code_original,
|
|
code as code,
|
|
texte as texte,
|
|
null::text as texte_court
|
|
FROM ttt
|
|
GROUP BY 1,2,3,4
|
|
;
|
|
|
|
-- Identification des services
|
|
DROP TABLE IF EXISTS temp.x_ref_service
|
|
;
|
|
|
|
CREATE TABLE temp.x_ref_service AS
|
|
SELECT
|
|
codelementniveau as code_original,
|
|
codelementniveau as code,
|
|
max(libelleniveau) as texte,
|
|
null::text as texte_court
|
|
FROM prod_pegase.niveaux
|
|
WHERE codtableniveau = 'Sections'
|
|
GROUP BY 1,2
|
|
;
|
|
|
|
-- Identification des spécialités
|
|
|
|
-- Identification des codes emploi
|
|
DROP TABLE IF EXISTS temp.x_ref_code_emploi
|
|
;
|
|
|
|
CREATE TABLE temp.x_ref_code_emploi AS
|
|
SELECT
|
|
substr(md5(emploi), 1, 5) as code_original,
|
|
substr(md5(emploi), 1, 5) as code,
|
|
emploi as texte,
|
|
null::text as texte_court
|
|
FROM prod_pegase.salaries
|
|
GROUP BY 1,2,3,4
|
|
;
|
|
|
|
-- Identification des types d'horaire
|
|
|
|
-- Identification des grilles
|
|
DROP TABLE IF EXISTS temp.x_ref_grille
|
|
;
|
|
|
|
CREATE TABLE temp.x_ref_grille AS
|
|
SELECT
|
|
champslibres as code_original,
|
|
champslibres as code,
|
|
champslibres as texte,
|
|
null::text as texte_court
|
|
FROM prod_pegase.salaries
|
|
GROUP BY 1,2,3,4
|
|
;
|
|
|
|
-- Identification des groupes de grilles
|
|
|
|
-- Identification des motifs d'arret
|
|
|
|
-- Identification des précisions du motif d'arrêt
|
|
|
|
-- Identification des motifs de visite médicale
|
|
|
|
-- Identification des circonstances d'accident du travail
|
|
|
|
-- Identification des lieux d'accident du travail
|
|
|
|
-- Identification de la nature de l'accident du travail
|
|
|
|
-- Identification des sièges d'accident du travail
|
|
|
|
-- Identification des listes de formations
|
|
|
|
DROP TABLE IF EXISTS temp.x_ref_section_analytique
|
|
;
|
|
|
|
CREATE TABLE temp.x_ref_section_analytique AS
|
|
select
|
|
identif as oid,
|
|
codsection as code_original,
|
|
codsection as code,
|
|
libellesection as texte,
|
|
null::text as texte_court
|
|
from prod_pegase.sectionsanalytiques
|
|
where numanalyse = (SELECT valeur::bigint FROM rh.t_divers WHERE code = 'PEGASE_VEN_PROV')
|
|
group by 1,2,3,4,5
|
|
;
|
|
|
|
-- Identification des rubriques de paie.
|
|
DROP TABLE IF EXISTS temp.x_ref_rubrique
|
|
;
|
|
|
|
CREATE TABLE temp.x_ref_rubrique AS
|
|
with rub_det_0 as (
|
|
select
|
|
rubriques.codrubrique,
|
|
flgbrutimpos = 1 and typrubrique = 1 as brut,
|
|
flgheurespayees = 1 and codrubrique::int < '410000' as hresp,
|
|
flgheurestravaillees = 1 and codrubrique::int < '410000' as hresw,
|
|
false as odns,
|
|
false as odnp,
|
|
flgchargessal = 1 as cosd,
|
|
flgchargespat = 1 as copa,
|
|
max(nom) as texte
|
|
from prod_pegase.rubriques
|
|
group by 1,2,3,4,5,6,7,8
|
|
)
|
|
, rub_det_1 as (
|
|
select
|
|
codrubrique,
|
|
max(texte) as texte,
|
|
bool_or(brut) or bool_or(odns) or bool_or(odnp) or bool_or(cosd) or bool_or(copa) AS p_detail,
|
|
false AS p_nombre,
|
|
bool_or(brut) or bool_or(odns) or bool_or(odnp) or bool_or(cosd) or bool_or(copa) AS p_base,
|
|
bool_or(hresp) AS p_heures_payees,
|
|
bool_or(hresw) AS p_heures_travaillees,
|
|
bool_or(brut) or bool_or(odnp) or bool_or(copa) AS p_masse_salariale,
|
|
bool_or(brut) AS p_brut,
|
|
false AS p_avantage_nature,
|
|
false AS p_frais_imposables,
|
|
bool_or(cosd) AS p_cotisation_salarie,
|
|
bool_or(copa) AS p_cotisation_patronale,
|
|
bool_or(odns) AS p_od_net_salarie,
|
|
false AS p_od_net_patronale,
|
|
bool_or(brut) or bool_or(cosd) AS p_net_imposable,
|
|
case when bool_or(cosd) then -1 else 1 end as c_net_imposable,
|
|
bool_or(brut) or bool_or(cosd) or bool_or(odns) AS p_net_a_payer,
|
|
case when bool_or(cosd) then -1 else 1 end as c_net_a_payer
|
|
from rub_det_0
|
|
group by 1
|
|
)
|
|
, rub_cum_0 as (
|
|
SELECT 'C000' as code, 'Ecart cumulé' as texte
|
|
UNION ALL
|
|
SELECT 'C001' as code, 'Heures payées' as texte
|
|
UNION ALL
|
|
SELECT 'C002' as code, 'Heures travaillées' as texte
|
|
UNION ALL
|
|
SELECT 'C003' as code, 'Net à payer' as texte
|
|
UNION ALL
|
|
SELECT 'C004' as code, 'Net imposable' as texte
|
|
UNION ALL
|
|
SELECT 'C005' as code, 'Avantage en nature' as texte
|
|
UNION ALL
|
|
SELECT 'C006' as code, 'Cotisations patronales' as texte
|
|
UNION ALL
|
|
SELECT 'C007' as code, 'Cotisations salariales' as texte
|
|
UNION ALL
|
|
SELECT 'C008' as code, 'Brut' as texte
|
|
UNION ALL
|
|
SELECT 'C009' as code, 'Heures Cadres Forfaits Jours' as texte
|
|
)
|
|
SELECT
|
|
codrubrique as code_original,
|
|
codrubrique as code,
|
|
texte as texte,
|
|
null::text as texte_court,
|
|
codrubrique::int as rang_edition,
|
|
false as p_cumul,
|
|
p_detail as p_detail,
|
|
p_nombre as p_nombre,
|
|
0 as s_nombre,
|
|
1 as c_nombre,
|
|
p_base as p_base,
|
|
1 as s_base,
|
|
1 as c_base,
|
|
false as p_heures_contrat,
|
|
0 as s_heures_contrat,
|
|
1 as c_heures_contrat,
|
|
p_heures_payees as p_heures_payees,
|
|
0 as s_heures_payees,
|
|
1 as c_heures_payees,
|
|
p_heures_travaillees as p_heures_travaillees,
|
|
0 as s_heures_travaillees,
|
|
1 as c_heures_travaillees,
|
|
p_masse_salariale as p_masse_salariale,
|
|
case when p_cotisation_patronale or p_od_net_patronale then 5 else 3 end as s_masse_salariale,
|
|
1 as c_masse_salariale,
|
|
p_brut as p_brut,
|
|
3 as s_brut,
|
|
1 as c_brut,
|
|
p_avantage_nature as p_avantage_nature,
|
|
3 as s_avantage_nature,
|
|
1 as c_avantage_nature,
|
|
p_frais_imposables as p_frais_imposables,
|
|
3 as s_frais_imposables,
|
|
1 as c_frais_imposables,
|
|
p_cotisation_salarie as p_cotisation_salarie,
|
|
3 as s_cotisation_salarie,
|
|
-1 as c_cotisation_salarie,
|
|
p_cotisation_patronale as p_cotisation_patronale,
|
|
5 as s_cotisation_patronale,
|
|
1 as c_cotisation_patronale,
|
|
p_od_net_salarie as p_od_net_salarie,
|
|
3 as s_od_net_salarie,
|
|
1 as c_od_net_salarie,
|
|
p_od_net_patronale as p_od_net_patronale,
|
|
5 as s_od_net_patronale,
|
|
1 as c_od_net_patronale,
|
|
p_net_imposable as p_net_imposable,
|
|
3 as s_net_imposable,
|
|
c_net_imposable as c_net_imposable,
|
|
p_net_a_payer as p_net_a_payer,
|
|
3 as s_net_a_payer,
|
|
c_net_a_payer as c_net_a_payer
|
|
FROM rub_det_1
|
|
UNION ALL
|
|
SELECT
|
|
code as code_original,
|
|
code as code,
|
|
texte as texte,
|
|
null::text as texte_court,
|
|
-1 as rang_edition,
|
|
true as p_cumul,
|
|
false as p_detail,
|
|
false as p_nombre,
|
|
0 as s_nombre,
|
|
1 as c_nombre,
|
|
false as p_base,
|
|
1 as s_base,
|
|
1 as c_base,
|
|
false as p_heures_contrat,
|
|
0 as s_heures_contrat,
|
|
1 as c_heures_contrat,
|
|
false as p_heures_payees,
|
|
0 as s_heures_payees,
|
|
1 as c_heures_payees,
|
|
false as p_heures_travaillees,
|
|
0 as s_heures_travaillees,
|
|
1 as c_heures_travaillees,
|
|
false as p_masse_salariale,
|
|
3 as s_masse_salariale,
|
|
1 as c_masse_salariale,
|
|
false as p_brut,
|
|
3 as s_brut,
|
|
1 as c_brut,
|
|
false as p_avantage_nature,
|
|
3 as s_avantage_nature,
|
|
1 as c_avantage_nature,
|
|
false as p_frais_imposables,
|
|
3 as s_frais_imposables,
|
|
1 as c_frais_imposables,
|
|
false as p_cotisation_salarie,
|
|
3 as s_cotisation_salarie,
|
|
1 as c_cotisation_salarie,
|
|
false as p_cotisation_patronale,
|
|
5 as s_cotisation_patronale,
|
|
1 as c_cotisation_patronale,
|
|
false as p_od_net_salarie,
|
|
3 as s_od_net_salarie,
|
|
1 as c_od_net_salarie,
|
|
false as p_od_net_patronale,
|
|
5 as s_od_net_patronale,
|
|
1 as c_od_net_patronale,
|
|
false as p_net_imposable,
|
|
3 as s_net_imposable,
|
|
1 as c_net_imposable,
|
|
false as p_net_a_payer,
|
|
3 as s_net_a_payer,
|
|
1 as c_net_a_payer
|
|
FROM rub_cum_0
|
|
;
|
|
|
|
]]></sqlcmd>
|
|
</NODE>
|
|
<NODE label="Pré-traitements">
|
|
<sqlcmd><![CDATA[
|
|
|
|
-- ALIMENTATION DES HISTORIQUES
|
|
|
|
|
|
DROP TABLE IF EXISTS w_sal
|
|
;
|
|
-- Traitement du cas où un même salarié peut avoir plusieurs date de début de validité pour une info : on prend les infos avec identif le plus élevé.
|
|
CREATE TEMP TABLE w_sal AS
|
|
select
|
|
codsalarie as sal_code_original,
|
|
datdebvalidite::date as date_debut,
|
|
((max(distinct array[identif::text, datfinvalidite::text]))[2])::date as date_fin,
|
|
max(identif) as identif,
|
|
(max(distinct array[identif::text, salaries.numsecu::text]))[2] as numsecu,
|
|
(max(distinct array[identif::text, salaries.nom::text]))[2] as nom,
|
|
(max(distinct array[identif::text, salaries.prenom::text]))[2] as prenom,
|
|
(max(distinct array[identif::text, salaries.nomjeunefille::text]))[2] as nomjeunefille,
|
|
((max(distinct array[identif::text, salaries.datnaissance::date::text]))[2])::date as datnaissance,
|
|
(max(distinct array[identif::text, salaries.typgenre::text]))[2] as typgenre,
|
|
(max(distinct array[identif::text, salaries.idsociete::text]))[2] as ent_code_original,
|
|
(max(distinct array[identif::text, salaries.codetab::text]))[2] as ets_code_original,
|
|
(max(distinct array[identif::text, salaries.adrcpost::text]))[2] as adrcpost,
|
|
(max(distinct array[identif::text, salaries.adr1::text]))[2] as adresse1,
|
|
(max(distinct array[identif::text, salaries.adr2::text]))[2] as adresse2,
|
|
(max(distinct array[identif::text, salaries.typsitfam::text]))[2] as typsitfam,
|
|
(max(distinct array[identif::text, salaries.typnationalite::text]))[2] as typnationalite,
|
|
lower((max(distinct array[identif::text, salaries.codinseeemploi2003::text]))[2]) as codinseeemploi2003,
|
|
(max(distinct array[identif::text, substr(md5(salaries.emploi::text), 1, 5)]))[2] as emploi,
|
|
(max(distinct array[identif::text, salaries.echelon::text]))[2] as echelon,
|
|
(max(distinct array[identif::text, salaries.niveau::text]))[2] as niveau,
|
|
(max(distinct array[identif::text, salaries.codcategorie::text]))[2] as codcategorie,
|
|
(max(distinct array[identif::text, salaries.typcontrat::text]))[2] as typcontrat,
|
|
(max(distinct array[identif::text, salaries.typtravail::text]))[2] as typtravail,
|
|
-- (max(distinct array[identif::text, salaries.codetab::text]))[2] as datfinvalidite::date,
|
|
((max(distinct array[identif::text, salaries.datanciennete::date::text]))[2])::date as datanciennete,
|
|
(max(distinct array[identif::text, salaries.codsection::text]))[2] as codsection,
|
|
(max(distinct array[identif::text, salaries.champslibres::text]))[2] as champslibres,
|
|
(max(distinct array[identif::numeric, (case when typtravail = 1 then 1.0 else coalesce(nullif(dadsusaltauxtppartiel / 10000.0, 0), 1.0) end)]))[2] as etp_contrat,
|
|
(max(distinct array[identif::text, (typtravail::text || '-'::text || case when typtravail = 1 then '10000'::text else lpad(coalesce(nullif(dadsusaltauxtppartiel, 0)::text, '10000'::text), 5, '0') end)]))[2] as code_ttt,
|
|
(max(distinct array[identif::text, salaries.codetab::text]))[2] as codetab -- code etablissement principal.
|
|
from prod_pegase.salaries
|
|
group by 1,2
|
|
;
|
|
|
|
-- SALARIES
|
|
DROP TABLE IF EXISTS temp.x_ref_salarie
|
|
;
|
|
|
|
CREATE TABLE temp.x_ref_salarie AS
|
|
select
|
|
sal_code_original AS matricule,
|
|
sal_code_original AS code,
|
|
sal_code_original AS code_original,
|
|
(max(array[date_debut::text, numsecu::text]))[2] as nir,
|
|
max(ent_code_original) as entreprise,
|
|
(max(distinct array[date_debut::text, nom::text]))[2] as nom,
|
|
(max(array[date_debut::text, nomjeunefille::text]))[2] as nom_naissance,
|
|
(max(array[date_debut::text, prenom::text]))[2] as prenom,
|
|
coalesce(max(datnaissance)::date, '1962-04-18'::date) as date_naissance,
|
|
max(case when typgenre = 'R' THEN 'M' else 'F' end) as sexe,
|
|
max(typnationalite) AS nationalite,
|
|
max(adrcpost) AS code_postal,
|
|
(max(array[date_debut::text, adresse1::text]))[2] AS adresse1,
|
|
(max(array[date_debut::text, adresse2::text]))[2] AS adresse2,
|
|
max(typsitfam) AS situation_famille,
|
|
max(date_debut) as date_debut,
|
|
max(date_fin) as date_fin,
|
|
min(date_debut) as date_entree_ets,
|
|
max(date_fin) as date_sortie_ets,
|
|
max(datanciennete) as date_anciennete,
|
|
-- Champs dédiés au public.
|
|
null::date AS date_entree_fp,
|
|
null::date AS date_entree_fph,
|
|
0 AS no_adeli,
|
|
0 AS code_cotisation_id,
|
|
0 AS matricule_retraite
|
|
from w_sal
|
|
--where codsalarie = '00825'
|
|
group by 1,2,3
|
|
;
|
|
|
|
-- Contrats (AUCUN des contrats PEGASE ne doit être chevauchant par matricule).
|
|
DROP TABLE IF EXISTS w_cnt_0
|
|
;
|
|
|
|
CREATE TEMP TABLE w_cnt_0 AS
|
|
WITH sanitized_dates as (
|
|
SELECT
|
|
identif as san_identif,
|
|
CASE WHEN lag(datentree::date) OVER w = datentree::date THEN
|
|
(lag(datsortie) OVER w + '1 day'::interval)::date
|
|
ELSE
|
|
datentree::date
|
|
END AS san_date_debut,
|
|
coalesce(datsortie::date, '2099-12-31'::date) AS san_date_fin
|
|
FROM prod_pegase.entreesorties
|
|
WINDOW w AS (PARTITION BY codsalarie ORDER BY datentree, coalesce(datsortie::date, '2099-12-31'::date))
|
|
)
|
|
SELECT
|
|
entreesorties.idsociete as ent_code_original,
|
|
entreesorties.codetab as ets_code_original,
|
|
codsalarie as sal_code_original,
|
|
identif,
|
|
-- codsalarie || '-'::text || identif AS cnt_code_original,
|
|
identif::text AS cnt_code_original,
|
|
codsalarie || '-'::text || to_char(san_date_debut, 'YYMMDD'::text) AS numero_contrat,
|
|
san_date_debut AS date_debut,
|
|
san_date_fin AS date_fin,
|
|
dadsumotifdebperiode AS motif_debut,
|
|
dadsumotiffinperiode AS motif_fin
|
|
FROM prod_pegase.entreesorties
|
|
JOIN sanitized_dates ON sanitized_dates.san_identif = entreesorties.identif
|
|
;
|
|
|
|
DROP TABLE IF EXISTS w_sal_0
|
|
;
|
|
|
|
CREATE TEMP TABLE w_sal_0 AS
|
|
select
|
|
sal_code_original,
|
|
case when lag(date_debut) over w is null
|
|
then '0001-01-01'::date
|
|
else date_debut
|
|
end as date_debut,
|
|
case when lead(date_debut) over w is null
|
|
then '2099-12-31'::date
|
|
else (lead(date_debut) over w - '1 day'::interval)::date
|
|
end as date_fin,
|
|
codinseeemploi2003,
|
|
emploi,
|
|
echelon,
|
|
niveau,
|
|
codcategorie,
|
|
typcontrat,
|
|
typtravail,
|
|
codsection,
|
|
etp_contrat,
|
|
code_ttt,
|
|
champslibres
|
|
from w_sal
|
|
window w as (partition by sal_code_original order by date_debut)
|
|
;
|
|
|
|
-- 1 ligne / contrat.
|
|
DROP TABLE IF EXISTS w_cnt
|
|
;
|
|
|
|
CREATE TEMP TABLE w_cnt AS
|
|
select
|
|
w_cnt_0.ent_code_original,
|
|
w_cnt_0.ets_code_original,
|
|
w_cnt_0.sal_code_original,
|
|
w_cnt_0.cnt_code_original,
|
|
w_cnt_0.numero_contrat,
|
|
w_cnt_0.date_debut,
|
|
w_cnt_0.date_fin,
|
|
w_cnt_0.motif_debut,
|
|
w_cnt_0.motif_fin,
|
|
(max(distinct array[identif::text, codinseeemploi2003]))[2] as codinseeemploi2003,
|
|
(max(distinct array[identif::text, emploi]))[2] as emploi,
|
|
(max(distinct array[identif::text, echelon]))[2] as echelon,
|
|
(max(distinct array[identif::text, niveau]))[2] as niveau,
|
|
(max(distinct array[identif::text, codcategorie]))[2] as codcategorie,
|
|
(max(distinct array[identif::text, typcontrat]))[2] as typcontrat,
|
|
(max(distinct array[identif::text, typtravail]))[2] as typtravail,
|
|
(max(distinct array[identif::text, codsection]))[2] as codsection,
|
|
(max(distinct array[identif::numeric, etp_contrat]))[2] as etp_contrat,
|
|
(max(distinct array[identif::text, code_ttt]))[2] as code_ttt
|
|
from w_cnt_0
|
|
join w_sal_0 on 1=1
|
|
and w_sal_0.sal_code_original = w_cnt_0.sal_code_original
|
|
and base.cti_overlaps(w_sal_0.date_debut, w_sal_0.date_fin, w_cnt_0.date_debut, w_cnt_0.date_fin)
|
|
group by 1,2,3,4,5,6,7,8,9
|
|
;
|
|
|
|
-- 1 ligne / avenant.
|
|
DROP TABLE IF EXISTS w_evo
|
|
;
|
|
|
|
CREATE TEMP TABLE w_evo AS
|
|
select
|
|
w_cnt_0.ent_code_original,
|
|
w_cnt_0.ets_code_original,
|
|
w_cnt_0.sal_code_original,
|
|
w_cnt_0.cnt_code_original,
|
|
w_cnt_0.numero_contrat,
|
|
w_cnt_0.date_debut as cnt_date_debut,
|
|
w_cnt_0.date_fin,
|
|
w_cnt_0.motif_debut,
|
|
w_cnt_0.motif_fin,
|
|
w_sal_0.date_debut as sal_date_debut,
|
|
w_sal_0.codinseeemploi2003,
|
|
w_sal_0.emploi,
|
|
w_sal_0.echelon,
|
|
w_sal_0.niveau,
|
|
w_sal_0.codcategorie,
|
|
w_sal_0.typcontrat,
|
|
w_sal_0.typtravail,
|
|
w_sal_0.codsection,
|
|
w_sal_0.etp_contrat,
|
|
w_sal_0.code_ttt,
|
|
w_sal_0.champslibres
|
|
from w_cnt_0
|
|
join w_sal_0 on 1=1
|
|
and w_sal_0.sal_code_original = w_cnt_0.sal_code_original
|
|
and base.cti_overlaps(w_sal_0.date_debut, w_sal_0.date_fin, w_cnt_0.date_debut, w_cnt_0.date_fin)
|
|
;
|
|
|
|
-- HISTORIQUE DES CONTRATS.
|
|
DROP TABLE IF EXISTS temp.x_hst_contrat
|
|
;
|
|
|
|
CREATE TABLE temp.x_hst_contrat AS
|
|
SELECT
|
|
row_number() over () as row_id,
|
|
ent_code_original,
|
|
ets_code_original,
|
|
ent_code_original||'-'||ets_code_original as ety_code_original,
|
|
sal_code_original,
|
|
cnt_code_original,
|
|
numero_contrat,
|
|
--cnt_uid, -- contrat universal id.
|
|
date_debut,
|
|
date_fin
|
|
from w_cnt
|
|
;
|
|
|
|
-- HISTORIQUE DES BULLETINS.
|
|
-- Plusieurs bulletins peuvent se chevaucher.
|
|
DROP TABLE IF EXISTS w_bul
|
|
;
|
|
|
|
CREATE TEMP TABLE w_bul AS
|
|
SELECT
|
|
idsociete as ent_code_original,
|
|
codetab as ets_code_original,
|
|
codsalarie as sal_code_original,
|
|
-- identif AS bul_code_original,
|
|
(codexercice||codbulletin)::text as bul_code_original,
|
|
case when to_char(datdebutpaie, 'YYYYMM') != codexercice||codperiode then base.cti_last_day((codexercice||codperiode||'01'::text)::date) else datdebutpaie::date end as date_debut, -- dates possiblement erron?es.
|
|
case when to_char(datfinpaie, 'YYYYMM') != codexercice||codperiode then base.cti_last_day((codexercice||codperiode||'01'::text)::date) else datfinpaie::date end as date_fin,
|
|
(codexercice||codperiode)::int as mois_paie
|
|
-- base.cti_last_day((codexercice||codperiode||'01'::text)::date) as date_paie
|
|
from prod_pegase.bulletins
|
|
where (codexercice||codperiode)::int >= to_char(rhp('rhprovider_start')::date, 'YYYYMM')
|
|
and (codexercice <> '' or codperiode <> '')
|
|
;
|
|
|
|
DROP TABLE IF EXISTS temp.x_hst_bulletin
|
|
;
|
|
|
|
CREATE TABLE temp.x_hst_bulletin AS
|
|
SELECT
|
|
w_bul.ent_code_original,
|
|
w_bul.ets_code_original,
|
|
w_bul.ent_code_original||'-'||w_bul.ets_code_original as ety_code_original,
|
|
w_bul.sal_code_original,
|
|
w_bul.bul_code_original,
|
|
w_bul.date_debut,
|
|
w_bul.date_fin,
|
|
w_bul.date_fin as date_paie,
|
|
w_bul.mois_paie,
|
|
row_number() over () as row_id,
|
|
row_number() over (order by ent_code_original, ets_code_original, sal_code_original, bul_code_original) as bul_id,
|
|
null::text as cnt_code_original, -- un bulletin est rattaché à un seul et unique contrat.
|
|
0 as est_hors_periode
|
|
from w_bul
|
|
;
|
|
|
|
-- Association avec le contrat correspondant aux dates.
|
|
-- Un bulletin est rattaché à un seul et unique contrat.
|
|
with toto as (
|
|
SELECT
|
|
x_hst_bulletin.row_id,
|
|
(max(array[x_hst_contrat.date_fin::text, x_hst_contrat.cnt_code_original]))[2] as cnt_code_original
|
|
from temp.x_hst_bulletin
|
|
join temp.x_hst_contrat on 1=1
|
|
and x_hst_contrat.sal_code_original = x_hst_bulletin.sal_code_original
|
|
and base.cti_overlaps(x_hst_contrat.date_debut, x_hst_contrat.date_fin, x_hst_bulletin.date_debut, x_hst_bulletin.date_fin)
|
|
group by 1
|
|
)
|
|
UPDATE temp.x_hst_bulletin set
|
|
cnt_code_original = toto.cnt_code_original
|
|
from toto
|
|
where x_hst_bulletin.row_id = toto.row_id
|
|
;
|
|
|
|
-- Association avec le contrat précédent.
|
|
with toto as (
|
|
SELECT
|
|
x_hst_bulletin.row_id,
|
|
(max(array[x_hst_contrat.date_fin::text, x_hst_contrat.cnt_code_original]))[2] as cnt_code_original
|
|
from temp.x_hst_bulletin
|
|
join temp.x_hst_contrat on 1=1
|
|
and x_hst_contrat.sal_code_original = x_hst_bulletin.sal_code_original
|
|
and x_hst_contrat.date_fin < x_hst_bulletin.date_debut
|
|
where x_hst_bulletin.cnt_code_original is null
|
|
group by 1
|
|
)
|
|
UPDATE temp.x_hst_bulletin set
|
|
cnt_code_original = toto.cnt_code_original,
|
|
est_hors_periode = 1
|
|
from toto
|
|
where x_hst_bulletin.row_id = toto.row_id
|
|
;
|
|
|
|
-- Association avec le contrat suivant.
|
|
with toto as (
|
|
SELECT
|
|
x_hst_bulletin.row_id,
|
|
(max(array[x_hst_contrat.date_fin::text, x_hst_contrat.cnt_code_original]))[2] as cnt_code_original
|
|
from temp.x_hst_bulletin
|
|
join temp.x_hst_contrat on 1=1
|
|
and x_hst_contrat.sal_code_original = x_hst_bulletin.sal_code_original
|
|
and x_hst_contrat.date_fin > x_hst_bulletin.date_debut
|
|
where x_hst_bulletin.cnt_code_original is null
|
|
group by 1
|
|
)
|
|
UPDATE temp.x_hst_bulletin set
|
|
cnt_code_original = toto.cnt_code_original,
|
|
est_hors_periode = 1
|
|
from toto
|
|
where x_hst_bulletin.row_id = toto.row_id
|
|
;
|
|
|
|
-- ICI : Tous les bulletins doivent avoir un contrat de renseigné.
|
|
-- A remonter plus tard dans une table spéciale avant suppression pour controle expert.
|
|
delete from temp.x_hst_bulletin
|
|
where cnt_code_original is null
|
|
;
|
|
|
|
-- La date min du premier contrat et/ou du premier bulletin détermine le début de la ventilation du salarié.
|
|
DROP TABLE IF EXISTS w_lim_sal
|
|
;
|
|
|
|
CREATE TEMP TABLE w_lim_sal AS
|
|
with toto as (
|
|
select
|
|
sal_code_original,
|
|
min(date_debut) as date_debut,
|
|
max(case when date_fin = '2099-12-31'::date then base.cti_last_day(current_date) else date_fin end) as date_fin
|
|
from temp.x_hst_contrat
|
|
group by 1
|
|
union all
|
|
select
|
|
sal_code_original,
|
|
min(date_debut) as date_debut,
|
|
max(case when date_fin = '2099-12-31'::date then base.cti_last_day(current_date) else date_fin end) as date_fin
|
|
from temp.x_hst_bulletin
|
|
group by 1
|
|
)
|
|
select
|
|
sal_code_original,
|
|
min(date_debut) as date_debut,
|
|
to_char(min(date_debut), 'YYYYMM')::int as mois_debut,
|
|
max(date_fin) as date_fin,
|
|
to_char(max(date_fin), 'YYYYMM')::int as mois_fin
|
|
from toto
|
|
group by 1
|
|
;
|
|
|
|
-- HISTORIQUE ETP Théorique contrat.
|
|
DROP TABLE IF EXISTS temp.x_hst_etp_contrat
|
|
;
|
|
|
|
CREATE TABLE temp.x_hst_etp_contrat AS
|
|
SELECT
|
|
w_evo.ent_code_original||'-'||w_evo.ets_code_original as ety_code_original,
|
|
w_evo.sal_code_original,
|
|
w_evo.cnt_code_original,
|
|
greatest(w_evo.sal_date_debut, w_evo.cnt_date_debut, w_lim_sal.date_debut) as date_effet,
|
|
w_evo.etp_contrat
|
|
from w_evo
|
|
join w_lim_sal on w_lim_sal.sal_code_original = w_evo.sal_code_original
|
|
;
|
|
|
|
-- HISTORIQUE CSP.
|
|
DROP TABLE IF EXISTS temp.x_hst_categorie_socio_professionnelle
|
|
;
|
|
|
|
CREATE TABLE temp.x_hst_categorie_socio_professionnelle AS
|
|
SELECT
|
|
w_evo.ent_code_original||'-'||w_evo.ets_code_original as ety_code_original,
|
|
w_evo.sal_code_original,
|
|
w_evo.cnt_code_original,
|
|
greatest(w_evo.sal_date_debut, w_evo.cnt_date_debut, w_lim_sal.date_debut) as date_effet,
|
|
w_evo.codinseeemploi2003 as categorie_socio_professionnelle_code_original
|
|
from w_evo
|
|
join w_lim_sal on w_lim_sal.sal_code_original = w_evo.sal_code_original
|
|
;
|
|
|
|
-- HISTORIQUE Motif de début.
|
|
DROP TABLE IF EXISTS temp.x_hst_motif_debut_contrat
|
|
;
|
|
|
|
CREATE TABLE temp.x_hst_motif_debut_contrat AS
|
|
SELECT
|
|
w_evo.ent_code_original||'-'||w_evo.ets_code_original as ety_code_original,
|
|
w_evo.sal_code_original,
|
|
w_evo.cnt_code_original,
|
|
greatest(w_evo.sal_date_debut, w_evo.cnt_date_debut, w_lim_sal.date_debut) as date_effet,
|
|
w_evo.motif_debut as motif_debut_code_original
|
|
from w_evo
|
|
join w_lim_sal on w_lim_sal.sal_code_original = w_evo.sal_code_original
|
|
;
|
|
|
|
-- HISTORIQUE Motif de fin.
|
|
DROP TABLE IF EXISTS temp.x_hst_motif_fin_contrat
|
|
;
|
|
|
|
CREATE TABLE temp.x_hst_motif_fin_contrat AS
|
|
SELECT
|
|
w_evo.ent_code_original||'-'||w_evo.ets_code_original as ety_code_original,
|
|
w_evo.sal_code_original,
|
|
w_evo.cnt_code_original,
|
|
greatest(w_evo.sal_date_debut, w_evo.cnt_date_debut, w_lim_sal.date_debut) as date_effet,
|
|
w_evo.motif_fin as motif_fin_code_original
|
|
from w_evo
|
|
join w_lim_sal on w_lim_sal.sal_code_original = w_evo.sal_code_original
|
|
;
|
|
|
|
|
|
-- HISTORIQUE Types de contrat.
|
|
DROP TABLE IF EXISTS temp.x_hst_type_contrat
|
|
;
|
|
|
|
CREATE TABLE temp.x_hst_type_contrat AS
|
|
SELECT
|
|
w_evo.ent_code_original||'-'||w_evo.ets_code_original as ety_code_original,
|
|
w_evo.sal_code_original,
|
|
w_evo.cnt_code_original,
|
|
greatest(w_evo.sal_date_debut, w_evo.cnt_date_debut, w_lim_sal.date_debut) as date_effet,
|
|
w_evo.typcontrat as type_contrat_code_original
|
|
from w_evo
|
|
join w_lim_sal on w_lim_sal.sal_code_original = w_evo.sal_code_original
|
|
;
|
|
|
|
-- -- HISTORIQUE CSP.
|
|
-- DROP TABLE IF EXISTS temp.x_hst_organisme_cotisation
|
|
-- ;
|
|
|
|
-- CREATE TABLE temp.x_hst_organisme_cotisation AS
|
|
-- SELECT
|
|
-- w_cnt.ent_code_original||'-'||w_cnt.ets_code_original as ety_code_original,
|
|
-- w_cnt.sal_code_original,
|
|
-- w_cnt.cnt_code_original,
|
|
-- greatest(w_cnt.date_debut, w_lim_sal.date_debut) as date_effet,
|
|
-- w_cnt.codinseeemploi2003 as categorie_socio_professionnelle_code_original
|
|
-- from w_cnt
|
|
-- join w_lim_sal on w_lim_sal.sal_code_original = w_cnt.sal_code_original
|
|
-- ;
|
|
|
|
-- HISTORIQUE CSP.
|
|
DROP TABLE IF EXISTS temp.x_hst_qualification
|
|
;
|
|
|
|
CREATE TABLE temp.x_hst_qualification AS
|
|
SELECT
|
|
w_evo.ent_code_original||'-'||w_evo.ets_code_original as ety_code_original,
|
|
w_evo.sal_code_original,
|
|
w_evo.cnt_code_original,
|
|
greatest(w_evo.sal_date_debut, w_evo.cnt_date_debut, w_lim_sal.date_debut) as date_effet,
|
|
w_evo.emploi as qualification_code_original
|
|
from w_evo
|
|
join w_lim_sal on w_lim_sal.sal_code_original = w_evo.sal_code_original
|
|
;
|
|
|
|
-- HISTORIQUE CSP.
|
|
DROP TABLE IF EXISTS temp.x_hst_statut
|
|
;
|
|
|
|
CREATE TABLE temp.x_hst_statut AS
|
|
SELECT
|
|
w_evo.ent_code_original||'-'||w_evo.ets_code_original as ety_code_original,
|
|
w_evo.sal_code_original,
|
|
w_evo.cnt_code_original,
|
|
greatest(w_evo.sal_date_debut, w_evo.cnt_date_debut, w_lim_sal.date_debut) as date_effet,
|
|
w_evo.codcategorie as statut_code_original
|
|
from w_evo
|
|
join w_lim_sal on w_lim_sal.sal_code_original = w_evo.sal_code_original
|
|
;
|
|
|
|
-- HISTORIQUE CSP.
|
|
DROP TABLE IF EXISTS temp.x_hst_type_temps_travail
|
|
;
|
|
|
|
CREATE TABLE temp.x_hst_type_temps_travail AS
|
|
SELECT
|
|
w_evo.ent_code_original||'-'||w_evo.ets_code_original as ety_code_original,
|
|
w_evo.sal_code_original,
|
|
w_evo.cnt_code_original,
|
|
greatest(w_evo.sal_date_debut, w_evo.cnt_date_debut, w_lim_sal.date_debut) as date_effet,
|
|
w_evo.code_ttt as type_temps_travail_code_original
|
|
from w_evo
|
|
join w_lim_sal on w_lim_sal.sal_code_original = w_evo.sal_code_original
|
|
;
|
|
|
|
-- HISTORIQUE CSP.
|
|
DROP TABLE IF EXISTS temp.x_hst_service
|
|
;
|
|
|
|
CREATE TABLE temp.x_hst_service AS
|
|
SELECT
|
|
w_evo.ent_code_original||'-'||w_evo.ets_code_original as ety_code_original,
|
|
w_evo.sal_code_original,
|
|
w_evo.cnt_code_original,
|
|
greatest(w_evo.sal_date_debut, w_evo.cnt_date_debut, w_lim_sal.date_debut) as date_effet,
|
|
w_evo.codsection as service_code_original
|
|
from w_evo
|
|
join w_lim_sal on w_lim_sal.sal_code_original = w_evo.sal_code_original
|
|
;
|
|
|
|
-- HISTORIQUE CSP.
|
|
DROP TABLE IF EXISTS temp.x_hst_code_emploi
|
|
;
|
|
|
|
CREATE TABLE temp.x_hst_code_emploi AS
|
|
SELECT
|
|
w_evo.ent_code_original||'-'||w_evo.ets_code_original as ety_code_original,
|
|
w_evo.sal_code_original,
|
|
w_evo.cnt_code_original,
|
|
greatest(w_evo.sal_date_debut, w_evo.cnt_date_debut, w_lim_sal.date_debut) as date_effet,
|
|
w_evo.emploi as code_emploi_code_original
|
|
from w_evo
|
|
join w_lim_sal on w_lim_sal.sal_code_original = w_evo.sal_code_original
|
|
;
|
|
|
|
-- HISTORIQUE GRILLE.
|
|
DROP TABLE IF EXISTS temp.x_hst_grille
|
|
;
|
|
|
|
CREATE TABLE temp.x_hst_grille AS
|
|
SELECT
|
|
w_evo.ent_code_original||'-'||w_evo.ets_code_original as ety_code_original,
|
|
w_evo.sal_code_original,
|
|
w_evo.cnt_code_original,
|
|
greatest(w_evo.sal_date_debut, w_evo.cnt_date_debut, w_lim_sal.date_debut) as date_effet,
|
|
w_evo.champslibres as grille_code_original
|
|
from w_evo
|
|
join w_lim_sal on w_lim_sal.sal_code_original = w_evo.sal_code_original
|
|
;
|
|
|
|
]]></sqlcmd>
|
|
</NODE>
|
|
<NODE label="Historique de la paie">
|
|
<sqlcmd><![CDATA[
|
|
|
|
DROP TABLE IF EXISTS temp.x_hst_paie
|
|
;
|
|
|
|
CREATE TABLE temp.x_hst_paie AS
|
|
with w_cum as (
|
|
select
|
|
bul_id,
|
|
ety_code_original,
|
|
sal_code_original,
|
|
cnt_code_original,
|
|
bul_code_original,
|
|
mois_paie,
|
|
date_debut,
|
|
date_fin,
|
|
date_paie,
|
|
unnest(rubriques) as rub,
|
|
unnest(valeurs) as val
|
|
from (
|
|
select
|
|
bulletins.bul_id,
|
|
bulletins.ety_code_original,
|
|
bulletins.sal_code_original,
|
|
bulletins.cnt_code_original,
|
|
bulletins.bul_code_original,
|
|
bulletins.mois_paie,
|
|
bulletins.date_debut,
|
|
bulletins.date_fin,
|
|
bulletins.date_paie,
|
|
array[
|
|
'C001',
|
|
'C002',
|
|
'C008',
|
|
'C007',
|
|
'C006',
|
|
'C004',
|
|
'C003',
|
|
'C009'] as rubriques,
|
|
array[
|
|
coalesce(nullif(nbrheures, ''), '0')::numeric,
|
|
coalesce(nullif(nbrheurestrav, ''), '0')::numeric,
|
|
coalesce(nullif(eumntbrut, ''), '0')::numeric,
|
|
coalesce(nullif(eumntchargessal, ''), '0')::numeric,
|
|
coalesce(nullif(eumntchargespat, ''), '0')::numeric,
|
|
coalesce(nullif(eumntimposable, ''), '0')::numeric,
|
|
coalesce(nullif(eumntnet, ''), '0')::numeric,
|
|
coalesce(nullif(nbrheuresreconstitue, ''), '0')::numeric] as valeurs
|
|
from temp.x_hst_bulletin as bulletins
|
|
join temp.x_ref_ets on x_ref_ets.ety_code_original = bulletins.ety_code_original
|
|
join prod_pegase.compteursbulletins on 1=1
|
|
and compteursbulletins.idsociete = bulletins.ent_code_original
|
|
and compteursbulletins.codetab = bulletins.ets_code_original
|
|
and compteursbulletins.codsalarie = bulletins.sal_code_original
|
|
and (compteursbulletins.codexercice||compteursbulletins.codbulletin)::text = bulletins.bul_code_original
|
|
where bulletins.mois_paie >= to_char(rhp('rhprovider_start')::date, 'YYYYMM')
|
|
) as suqb)
|
|
select
|
|
bulletins.bul_id,
|
|
bulletins.ety_code_original,
|
|
bulletins.sal_code_original,
|
|
bulletins.cnt_code_original,
|
|
bulletins.bul_code_original,
|
|
bulletins.date_debut,
|
|
bulletins.date_fin,
|
|
bulletins.mois_paie as mois_activite,
|
|
bulletins.date_paie,
|
|
bulletins.mois_paie,
|
|
codrubrique as rub_code_original,
|
|
coalesce(nullif(eubasapc, ''), '0')::numeric as base,
|
|
coalesce(nullif(eutausalapc, ''), '0')::numeric as txsal,
|
|
coalesce(nullif(eumntsalapc, ''), '0')::numeric as mntsal,
|
|
coalesce(nullif(eutaupatapc, ''), '0')::numeric as txpat,
|
|
coalesce(nullif(eumntpatapc, ''), '0')::numeric as mntpat
|
|
from temp.x_hst_bulletin as bulletins
|
|
join temp.x_ref_ets on x_ref_ets.ety_code_original = bulletins.ety_code_original
|
|
join prod_pegase.bulletinsdetail on 1=1
|
|
and bulletinsdetail.idsociete = bulletins.ent_code_original
|
|
and bulletinsdetail.codetab = bulletins.ets_code_original
|
|
and bulletinsdetail.codsalarie = bulletins.sal_code_original
|
|
and (bulletinsdetail.codexercice||bulletinsdetail.codbulletin)::text = bulletins.bul_code_original
|
|
where 1=1
|
|
AND bulletins.mois_paie >= to_char(rhp('rhprovider_start')::date, 'YYYYMM')
|
|
AND (1!=1
|
|
or eumntsalapc != ''
|
|
or eumntpatapc != ''
|
|
or eubasapc != '')
|
|
UNION ALL
|
|
select
|
|
bul_id,
|
|
ety_code_original,
|
|
sal_code_original,
|
|
cnt_code_original,
|
|
bul_code_original,
|
|
date_debut,
|
|
date_fin,
|
|
mois_paie as mois_activite,
|
|
date_paie,
|
|
mois_paie,
|
|
rub as rub_code_original,
|
|
case when rub in ('C001', 'C002', 'C009') then val::numeric else 0::numeric end as base,
|
|
0 as txsal,
|
|
case
|
|
when rub in ('C003', 'C004', 'C008') then val::numeric
|
|
when rub = 'C007' then -val::numeric
|
|
else 0::numeric end as mnt_sal,
|
|
0 as txpat,
|
|
case when rub = 'C006' then val::numeric else 0::numeric end as mnt_pat
|
|
from w_cum
|
|
;
|
|
|
|
-- #specifique Forfaits Jours & Vacations (on renseigne dans base le nombre d'heures contractuel d'après le champ "heures reconstituées").
|
|
with liste_rub_fj as (
|
|
select t_rubriques.code_original
|
|
from rh.t_listes
|
|
join rh.t_listes_contenu on t_listes_contenu.liste_id = t_listes.oid
|
|
join rh.t_rubriques on t_rubriques.oid = t_listes_contenu.to_id
|
|
where t_listes.code = 'CTI_PEGASE_FTJ'
|
|
)
|
|
, fj_sal as (
|
|
select
|
|
bul_id,
|
|
sal_code_original
|
|
from temp.x_hst_paie
|
|
where true
|
|
and rub_code_original in (select code_original from liste_rub_fj)
|
|
and base = 0
|
|
)
|
|
, sal_etp as (
|
|
select
|
|
x_hst_etp_contrat.ety_code_original,
|
|
x_hst_etp_contrat.sal_code_original,
|
|
date_effet as date_debut,
|
|
lead(date_effet - 1, 1, '2099-12-31'::date) over w as date_fin,
|
|
etp_contrat
|
|
from temp.x_hst_etp_contrat
|
|
join fj_sal on fj_sal.sal_code_original = x_hst_etp_contrat.sal_code_original
|
|
group by 1,2,3 ,5
|
|
window w as (partition by x_hst_etp_contrat.sal_code_original order by date_effet)
|
|
)
|
|
, new_data_fj as (
|
|
select
|
|
x_hst_paie.bul_id,
|
|
coalesce(etp_contrat, 1.0) * x_hst_paie.base as base
|
|
from temp.x_hst_paie
|
|
join fj_sal on fj_sal.bul_id = x_hst_paie.bul_id
|
|
join sal_etp on 1=1
|
|
and sal_etp.ety_code_original = x_hst_paie.ety_code_original
|
|
and sal_etp.sal_code_original = x_hst_paie.sal_code_original
|
|
and x_hst_paie.date_paie between sal_etp.date_debut and sal_etp.date_fin
|
|
where 1=1
|
|
and x_hst_paie.rub_code_original = 'C009')
|
|
update temp.x_hst_paie set
|
|
base = new_data_fj.base
|
|
from new_data_fj
|
|
where 1=1
|
|
and new_data_fj.bul_id = x_hst_paie.bul_id
|
|
and x_hst_paie.rub_code_original in (select code_original from liste_rub_fj)
|
|
;
|
|
|
|
-- Alimentation de la base de la rubrique forfait jour à partir de la base d'une rubrique référence avec la condition de nombre de jour pour définir les temps pleins et affecter les heures contrat
|
|
|
|
with parametrage_pegase_forfait_jour as (
|
|
select
|
|
valeur
|
|
,split_part(valeur, '|', 1) as rubrique_ref -- rubrique source
|
|
,split_part(valeur, '|', 2) as rubrique_cible -- rubrique cible
|
|
,split_part(valeur, '|', 3)::int as max_jour -- valeur de condition du nombre de jour maximum à prendre en compte pour distinguer les temps complets des temps partiels
|
|
from rh.t_divers
|
|
where code = 'PEGASE_FORFAIT_JOUR'
|
|
)
|
|
, forfait_cadre as (
|
|
select
|
|
sal_code_original,
|
|
mois_paie,
|
|
base,
|
|
bul_id
|
|
from temp.x_hst_paie
|
|
where rub_code_original in (select rubrique_ref from parametrage_pegase_forfait_jour)
|
|
)
|
|
, modif_base as (
|
|
select
|
|
x_hst_paie.sal_code_original as sal_code_original,
|
|
x_hst_paie.mois_paie as mois_paie,
|
|
x_hst_paie.base,
|
|
x_hst_paie.rub_code_original,
|
|
forfait_cadre.bul_id as bul_id,
|
|
case when forfait_cadre.base < (select max_jour from parametrage_pegase_forfait_jour) then forfait_cadre.base*7 else 151.67 end as forfait_jour_base -- si le nombre de jour (rubrique source) est inférieur au nombre de jour max défini alors on multiplie la base de la rubrique source par 7 et on affecte cette valeur à la rubrique cible sinon on affecte 151,7 (temps plein)
|
|
from temp.x_hst_paie
|
|
join forfait_cadre on forfait_cadre.sal_code_original = x_hst_paie.sal_code_original and forfait_cadre.mois_paie = x_hst_paie.mois_paie and forfait_cadre.bul_id = x_hst_paie.bul_id
|
|
where x_hst_paie.rub_code_original in (select rubrique_cible from parametrage_pegase_forfait_jour)
|
|
and (select valeur from parametrage_pegase_forfait_jour) is not null and (select valeur from parametrage_pegase_forfait_jour) <> ''
|
|
)
|
|
|
|
update temp.x_hst_paie set
|
|
base = modif_base.forfait_jour_base
|
|
from modif_base
|
|
where 1=1
|
|
and x_hst_paie.sal_code_original = modif_base.sal_code_original
|
|
and x_hst_paie.mois_paie = modif_base.mois_paie
|
|
and x_hst_paie.bul_id = modif_base.bul_id
|
|
and x_hst_paie.base is distinct from modif_base.forfait_jour_base
|
|
and x_hst_paie.rub_code_original in (select rubrique_cible from parametrage_pegase_forfait_jour)
|
|
|
|
;
|
|
|
|
]]></sqlcmd>
|
|
</NODE>
|
|
<NODE label="Ventilation analytique">
|
|
<sqlcmd><![CDATA[
|
|
|
|
-- Recencement de la ventilation ana.
|
|
DROP TABLE IF EXISTS temp.x_ventilation
|
|
;
|
|
|
|
CREATE TABLE temp.x_ventilation AS
|
|
with base as (
|
|
select
|
|
x_hst_bulletin.bul_id,
|
|
sectionsanalytiques.identif as section_analytique_id,
|
|
coalesce(nullif(repartitionpourcent, 0), 100.0) as pct
|
|
from prod_pegase.sectionsbulletin
|
|
join prod_pegase.sectionsanalytiques on 1=1
|
|
and sectionsanalytiques.codsection = sectionsbulletin.codsection
|
|
and sectionsanalytiques.numanalyse = sectionsbulletin.numanalyse
|
|
join temp.x_hst_bulletin on 1=1
|
|
and x_hst_bulletin.ent_code_original = sectionsbulletin.idsociete
|
|
and x_hst_bulletin.ets_code_original = sectionsbulletin.codetab
|
|
and x_hst_bulletin.sal_code_original = sectionsbulletin.codsalarie
|
|
and x_hst_bulletin.bul_code_original = (sectionsbulletin.codexercice||sectionsbulletin.codbulletin)::text
|
|
where sectionsbulletin.numanalyse = (SELECT valeur::bigint FROM rh.t_divers WHERE code = 'PEGASE_VEN_PROV'))
|
|
, ven as (
|
|
select
|
|
bul_id,
|
|
section_analytique_id,
|
|
base.cti_division(pct, sum(pct) over (partition by bul_id)) as ratio
|
|
from base)
|
|
select
|
|
bul_id,
|
|
section_analytique_id,
|
|
sectionsanalytiques.codsection as section_analytique_code_original,
|
|
sum(ratio) as ratio
|
|
from ven
|
|
join prod_pegase.sectionsanalytiques on sectionsanalytiques.identif = section_analytique_id
|
|
group by 1,2,3
|
|
;
|
|
|
|
]]></sqlcmd>
|
|
</NODE>
|
|
</NODE>
|
|
<NODE name="PROD" label="RECUPERATION DES DONNEES DE PRODUCTION">
|
|
<NODE name="PROD_COMMON" type="common" />
|
|
</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[
|
|
|
|
]]></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>
|