<?xml version="1.0" encoding="ISO-8859-1"?>
|
|
<ROOT>
|
|
<NODE name="INIT" label="INITIALISATIONS">
|
|
<NODE label="Pre-traitements des tables prestataire">
|
|
<sqlcmd><![CDATA[
|
|
|
|
-- TRAITEMENT de la table prod_cegid.histosalarie
|
|
DROP TABLE IF EXISTS w_histosalarie
|
|
;
|
|
|
|
CREATE TEMP TABLE w_histosalarie AS
|
|
WITH w_temp as (
|
|
SELECT
|
|
phs_dateretro::date,
|
|
phs_salarie,
|
|
(max(ARRAY[extract(EPOCH FROM phs_dateapplic)::text, phs_codeemploi]))[2] AS phs_codeemploi,
|
|
(max(ARRAY[extract(EPOCH FROM phs_dateapplic)::text, phs_condemploi]))[2] AS phs_condemploi,
|
|
(max(ARRAY[extract(EPOCH FROM phs_dateapplic)::text, phs_dadscat]))[2] AS phs_dadscat,
|
|
(max(ARRAY[extract(EPOCH FROM phs_dateapplic)::text, phs_dadsprof]))[2] AS phs_dadsprof,
|
|
(max(ARRAY[extract(EPOCH FROM phs_dateapplic)::numeric, phs_horairemois]))[2] AS phs_horairemois,
|
|
(max(ARRAY[extract(EPOCH FROM phs_dateapplic)::numeric, phs_ttauxpartiel]))[2] AS phs_ttauxpartiel
|
|
FROM prod_cegid.histosalarie
|
|
GROUP BY 1,2
|
|
)
|
|
SELECT
|
|
phs_dateretro AS date_debut,
|
|
coalesce((lag(phs_dateretro) over w - '1 day'::interval)::date, '2099-12-31'::date) AS date_fin,
|
|
0::numeric as nb_heures,
|
|
phs_salarie,
|
|
phs_codeemploi,
|
|
phs_condemploi,
|
|
phs_dadscat,
|
|
phs_dadsprof,
|
|
phs_horairemois,
|
|
phs_ttauxpartiel
|
|
FROM w_temp
|
|
WINDOW w as (partition by phs_salarie order by phs_dateretro desc)
|
|
;
|
|
|
|
]]></sqlcmd>
|
|
</NODE>
|
|
<NODE label="Pre-traitements des tables Cegid">
|
|
<condition><![CDATA[
|
|
|
|
-- Si la table w_histosalarie n'a pas de colonne phs_horairemois, on la rajoute à la volée.
|
|
select count(*) = 0
|
|
from information_schema.columns
|
|
where 1=1
|
|
and table_schema = 'prod_cegid'
|
|
and table_name = 'histosalarie'
|
|
and column_name = 'phs_horairemois'
|
|
;
|
|
|
|
]]></condition>
|
|
<sqlcmd><![CDATA[
|
|
|
|
-- Création de la colonne.
|
|
ALTER TABLE w_histosalarie ADD COLUMN phs_horairemois numeric;
|
|
|
|
-- Alimentation de la colonne.
|
|
UPDATE w_histosalarie SET
|
|
phs_horairemois = 0
|
|
;
|
|
|
|
]]></sqlcmd>
|
|
</NODE>
|
|
<NODE label="Pre-traitements des tables prestataire">
|
|
<sqlcmd><![CDATA[
|
|
|
|
UPDATE w_histosalarie SET
|
|
nb_heures = phs_horairemois::numeric
|
|
WHERE nb_heures != phs_horairemois::numeric
|
|
;
|
|
|
|
-- TRAITEMENT de la table prod_cegid.contrattravail
|
|
DROP TABLE IF EXISTS w_contrattravail
|
|
;
|
|
|
|
CREATE TEMP TABLE w_contrattravail AS
|
|
WITH cnt1 as (
|
|
SELECT
|
|
pci_debutcontrat::date AS date_debut,
|
|
(CASE WHEN pci_fincontrat::date = '1900-01-01'
|
|
THEN (case when row_number() over w_desc = 1 then '2099-12-31' else lag(pci_debutcontrat) over w_desc - '1 day'::interval end)
|
|
ELSE (case when pci_fincontrat >= lag(pci_debutcontrat) over w_desc then lag(pci_debutcontrat) over w_desc - '1 day'::interval else pci_fincontrat end)
|
|
END)::date
|
|
AS date_fin,
|
|
*
|
|
FROM prod_cegid.contrattravail
|
|
window w_desc as (partition by pci_salarie order by pci_debutcontrat desc)
|
|
)
|
|
SELECT
|
|
((CASE WHEN date_fin = '2099-12-31'::date then now() else date_fin END)::date - date_debut + 1) AS duree,
|
|
to_char(date_debut, 'YYYYMM') AS mois,
|
|
pci_salarie::text||lpad(pci_ordre,4,'0') AS numero_contrat,
|
|
*
|
|
FROM cnt1
|
|
;
|
|
|
|
-- #correction
|
|
-- Type de contrat CCD => CDD.
|
|
UPDATE w_contrattravail
|
|
SET pci_typecontrat = 'CDD'
|
|
WHERE pci_typecontrat = 'CCD'
|
|
;
|
|
|
|
-- Ventilation mensuelle des contrats
|
|
DROP TABLE IF EXISTS w_contrattravail_mois
|
|
;
|
|
|
|
CREATE TEMP TABLE w_contrattravail_mois AS
|
|
SELECT
|
|
GREATEST(p_calendrier_mois.date_debut, w_contrattravail.date_debut) AS date_debut_mv, -- date debut mois ventilé
|
|
LEAST(p_calendrier_mois.date_fin, w_contrattravail.date_fin) AS date_fin_mv, -- date fin mois ventilé
|
|
p_calendrier_mois.mois AS mois_mv, -- mois ventilation
|
|
w_contrattravail.*
|
|
FROM w_contrattravail
|
|
JOIN base.p_calendrier_mois ON base.cti_overlaps(w_contrattravail.date_debut, w_contrattravail.date_fin, p_calendrier_mois.date_debut, p_calendrier_mois.date_fin)
|
|
;
|
|
|
|
-- TRAITEMENT de la table prod_cegid.paieencours
|
|
DROP TABLE IF EXISTS w_paieencours
|
|
;
|
|
|
|
CREATE TEMP TABLE w_paieencours AS
|
|
SELECT
|
|
ppu_datedebut::date AS date_debut,
|
|
ppu_datefin::date AS date_fin,
|
|
to_char(ppu_datedebut::date, 'YYYYMM') AS mois,
|
|
*
|
|
FROM prod_cegid.paieencours
|
|
;
|
|
|
|
-- Type temps de travail à blanc
|
|
UPDATE w_histosalarie
|
|
SET phs_condemploi = 'C'
|
|
WHERE 1=1
|
|
AND phs_condemploi = ''
|
|
AND phs_ttauxpartiel = 0
|
|
;
|
|
|
|
-- Taux temps partiel anormal
|
|
UPDATE w_histosalarie
|
|
SET phs_ttauxpartiel = round(phs_ttauxpartiel / 100,0)
|
|
WHERE phs_ttauxpartiel > 1000
|
|
;
|
|
|
|
-- #specifique Parc à caen 243 récup. nb heures pour les forfaits jours notamment.
|
|
UPDATE w_histosalarie
|
|
SET nb_heures = case when phs_condemploi = 'C' then 151.6700 else round(phs_ttauxpartiel / 100.0 * 151.67, 4) end
|
|
WHERE @phs_horairemois = 0
|
|
;
|
|
|
|
]]></sqlcmd>
|
|
</NODE>
|
|
<NODE label="Pre-traitements des tables Cegid (paieencours)">
|
|
<condition><![CDATA[
|
|
|
|
-- Si la table paieencours n'a pas de colonne ppu_travailn4, on la rajoute à la volée.
|
|
select count(*) = 0
|
|
from information_schema.columns
|
|
where 1=1
|
|
and table_schema = 'prod_cegid'
|
|
and table_name = 'paieencours'
|
|
and column_name = 'ppu_travailn4'
|
|
;
|
|
|
|
]]></condition>
|
|
<sqlcmd><![CDATA[
|
|
|
|
-- Création de la colonne.
|
|
ALTER TABLE w_paieencours ADD COLUMN ppu_travailn4 character(3)
|
|
;
|
|
|
|
-- Alimentation de la colonne.
|
|
UPDATE w_paieencours SET
|
|
ppu_travailn4 = ''
|
|
;
|
|
|
|
]]></sqlcmd>
|
|
</NODE>
|
|
<NODE name="INIT" type="common" />
|
|
<NODE label="Mise à jour des informations permanentes">
|
|
<sqlcmd><![CDATA[
|
|
|
|
-- Màj des Entreprises
|
|
INSERT INTO rh.t_entreprises(code, texte, texte_court, code_original)
|
|
SELECT so_societe, so_libelle, substr(so_libelle,1,50), so_societe
|
|
FROM prod_cegid.societe
|
|
WHERE so_societe NOT IN (SELECT code_original FROM rh.t_entreprises)
|
|
GROUP BY 1,2,3,4
|
|
;
|
|
|
|
-- Màj des Etablissements
|
|
INSERT INTO rh.t_etablissements(code, texte, texte_court, code_original, entreprise_id)
|
|
SELECT et_etablissement, et_libelle, substr(et_libelle,1,50), et_etablissement, t_entreprises.oid
|
|
FROM prod_cegid.etabliss
|
|
JOIN rh.t_entreprises ON t_entreprises.code_original = etabliss.et_etablissement
|
|
WHERE et_etablissement NOT IN (SELECT code_original FROM rh.t_etablissements)
|
|
GROUP BY 1,2,3,4,5
|
|
;
|
|
|
|
-- Màj des catégories socio-professionnelles (basé sur une table de faits)
|
|
INSERT INTO rh.t_categories_socio_professionnelle(code, code_original, texte, texte_court)
|
|
SELECT lower(phs_codeemploi), lower(phs_codeemploi), lower(phs_codeemploi), substr(lower(phs_codeemploi), 1, 50)
|
|
FROM w_histosalarie
|
|
WHERE lower(phs_codeemploi) NOT IN (SELECT code_original FROM rh.t_categories_socio_professionnelle)
|
|
GROUP BY 1,2,3,4
|
|
;
|
|
|
|
-- @TODO: Màj des groupes cotisants : code 'PTG' ?
|
|
INSERT INTO rh.t_groupes_cotisant(code, code_original, texte, texte_court)
|
|
SELECT cc_code, cc_code, cc_libelle, substr(cc_abrege,1,50)
|
|
FROM prod_cegid.choixcod
|
|
WHERE 1=1
|
|
AND cc_type = 'PSQ'
|
|
AND cc_code NOT IN (SELECT code_original FROM rh.t_groupes_cotisant)
|
|
GROUP BY 1,2,3,4
|
|
;
|
|
|
|
-- Màj des motifs de début de contrat
|
|
INSERT INTO rh.t_motifs_debut_contrat(code, code_original, texte, texte_court)
|
|
SELECT trim(psa_motifentree), trim(psa_motifentree), trim(psa_motifentree), trim(substr(psa_motifentree,1,50))
|
|
FROM prod_cegid.salaries
|
|
WHERE trim(psa_motifentree) NOT IN (SELECT code_original FROM rh.t_motifs_debut_contrat)
|
|
GROUP BY 1,2,3,4
|
|
;
|
|
|
|
-- Màj des nationalités
|
|
INSERT INTO rh.t_nationalites(code, texte, texte_court, code_original)
|
|
SELECT psa_nationalite, psa_nationalite, substr(psa_nationalite,1,50), psa_nationalite
|
|
FROM prod_cegid.salaries
|
|
WHERE psa_nationalite NOT IN (SELECT code_original FROM rh.t_nationalites)
|
|
GROUP BY 1,2,3,4
|
|
;
|
|
|
|
-- Màj des organismes de cotisation (attention, possibilité de codes identiques par établissement (pog_etablissement non remonté))
|
|
INSERT INTO rh.t_organismes_cotisation(code_original, code, texte, texte_court)
|
|
SELECT pog_organisme, pog_organisme, max(pog_libelle), substr(max(pog_libelle), 1, 50)
|
|
FROM prod_cegid.organismepaie
|
|
WHERE pog_organisme NOT IN (SELECT code_original FROM rh.t_organismes_cotisation)
|
|
GROUP BY 1,2
|
|
;
|
|
|
|
-- Màj des qualifications
|
|
INSERT INTO rh.t_qualifications(code_original, code, texte, texte_court)
|
|
WITH w_qual AS (
|
|
SELECT
|
|
ltrim(pmi_code, '0') as code_original,
|
|
ltrim(pmi_code, '0') as code,
|
|
pmi_libelle as texte,
|
|
substr(pmi_libelle, 1, 50) as texte_court
|
|
FROM prod_cegid.minimumconvent
|
|
WHERE 1=1
|
|
AND pmi_nature = 'QUA'
|
|
AND ltrim(pmi_code, '0') NOT IN (SELECT code_original FROM rh.t_qualifications)
|
|
AND (select valeur = 'QUALIFICATION' FROM rh.t_divers WHERE code = 'CEGID_QUALIFICATION')
|
|
GROUP BY 1,2,3,4
|
|
UNION ALL
|
|
SELECT
|
|
cc_code as code_original,
|
|
cc_code as code,
|
|
cc_libelle as texte,
|
|
substr(cc_abrege,1,50) as texte_court
|
|
FROM prod_cegid.choixcod
|
|
WHERE 1=1
|
|
AND cc_type = 'PLE'
|
|
AND cc_code NOT IN (SELECT code_original FROM rh.t_qualifications)
|
|
AND (select valeur = 'EMPLOI' FROM rh.t_divers WHERE code = 'CEGID_QUALIFICATION')
|
|
GROUP BY 1,2,3,4
|
|
UNION
|
|
SELECT
|
|
ppu_libelleemploi as code_original,
|
|
ppu_libelleemploi as code,
|
|
ppu_libelleemploi as texte,
|
|
substr(ppu_libelleemploi, 1, 50) as texte_court
|
|
FROM prod_cegid.paieencours
|
|
WHERE 1=1
|
|
AND ppu_libelleemploi NOT IN (SELECT code_original FROM rh.t_qualifications)
|
|
AND (select valeur = 'EMPLOI' FROM rh.t_divers WHERE code = 'CEGID_QUALIFICATION')
|
|
GROUP BY 1,2,3,4
|
|
)
|
|
SELECT code_original, max(code), max(texte), max(texte_court) FROM w_qual
|
|
GROUP BY 1
|
|
;
|
|
|
|
-- Màj des rubriques
|
|
INSERT INTO rh.t_rubriques(code, texte, texte_court, code_original, rang_edition)
|
|
SELECT
|
|
phb_rubrique,
|
|
(max(ARRAY[phb_datefin::text,phb_libelle]))[2],
|
|
substr((max(ARRAY[phb_datefin::text,phb_libelle]))[2],1,50),
|
|
phb_rubrique,
|
|
max((phb_ordreetat::text||rpad(regexp_replace(phb_rubrique, '[^0-9]', '', 'g'), 5, '0'))::numeric)
|
|
FROM prod_cegid.histobulletin
|
|
WHERE 1=1
|
|
AND phb_rubrique NOT IN (SELECT code_original FROM rh.t_rubriques)
|
|
AND (select valeur = '0' from rh.t_divers where code = 'OPT_STD_HP')
|
|
GROUP BY 1,4
|
|
UNION ALL
|
|
SELECT
|
|
phb_rubrique,
|
|
(max(ARRAY[phb_datefin::text,phb_libelle]))[2],
|
|
substr((max(ARRAY[phb_datefin::text,phb_libelle]))[2],1,50),
|
|
phb_rubrique||'-'||phb_ordreetat::text,
|
|
max((phb_ordreetat::text||rpad(regexp_replace(phb_rubrique, '[^0-9]', '', 'g'), 5, '0'))::numeric)
|
|
FROM prod_cegid.histobulletin
|
|
WHERE 1=1
|
|
AND phb_rubrique||'-'||phb_ordreetat::text NOT IN (SELECT code_original FROM rh.t_rubriques)
|
|
AND (select valeur = '1' from rh.t_divers where code = 'OPT_STD_HP')
|
|
GROUP BY 1,4
|
|
;
|
|
|
|
-- création des rubriques CTI de cumul
|
|
INSERT INTO rh.t_rubriques(code, texte, texte_court, code_original, rang_edition)
|
|
SELECT 'C000', 'Ecart cumulé', 'Ecart cumulé', 'C000', -1
|
|
WHERE 'C000' NOT IN (SELECT code_original FROM rh.t_rubriques)
|
|
;
|
|
|
|
INSERT INTO rh.t_rubriques(code, texte, texte_court, code_original, rang_edition)
|
|
SELECT 'C001', 'Brut avant abattement', 'Brut avant abattement', 'C001', -1
|
|
WHERE 'C001' NOT IN (SELECT code_original FROM rh.t_rubriques)
|
|
;
|
|
|
|
INSERT INTO rh.t_rubriques(code, texte, texte_court, code_original, rang_edition)
|
|
SELECT 'C002', 'Brut après abattement', 'Brut après abattement', 'C002', -1
|
|
WHERE 'C002' NOT IN (SELECT code_original FROM rh.t_rubriques)
|
|
;
|
|
|
|
INSERT INTO rh.t_rubriques(code, texte, texte_court, code_original, rang_edition)
|
|
SELECT 'C007', 'Charges patronales', 'Charges patronales', 'C007', -1
|
|
WHERE 'C007' NOT IN (SELECT code_original FROM rh.t_rubriques)
|
|
;
|
|
|
|
INSERT INTO rh.t_rubriques(code, texte, texte_court, code_original, rang_edition)
|
|
SELECT 'C008', 'Charges salariales', 'Charges salariales', 'C008', -1
|
|
WHERE 'C008' NOT IN (SELECT code_original FROM rh.t_rubriques)
|
|
;
|
|
|
|
INSERT INTO rh.t_rubriques(code, texte, texte_court, code_original, rang_edition)
|
|
SELECT 'C020', 'Heures travaillées', 'Heures travaillées', 'C020', -1
|
|
WHERE 'C020' NOT IN (SELECT code_original FROM rh.t_rubriques)
|
|
;
|
|
|
|
INSERT INTO rh.t_rubriques(code, texte, texte_court, code_original, rang_edition)
|
|
SELECT 'C021', 'Heures payées', 'Heures payées', 'C021', -1
|
|
WHERE 'C021' NOT IN (SELECT code_original FROM rh.t_rubriques)
|
|
;
|
|
|
|
INSERT INTO rh.t_rubriques(code, texte, texte_court, code_original, rang_edition)
|
|
SELECT 'C022', 'Heures normales', 'Heures normales', 'C022', -1
|
|
WHERE 'C022' NOT IN (SELECT code_original FROM rh.t_rubriques)
|
|
;
|
|
|
|
INSERT INTO rh.t_rubriques(code, texte, texte_court, code_original, rang_edition)
|
|
SELECT 'C009', 'Net imposable', 'Net imposable', 'C009', -1
|
|
WHERE 'C009' NOT IN (SELECT code_original FROM rh.t_rubriques)
|
|
;
|
|
|
|
INSERT INTO rh.t_rubriques(code, texte, texte_court, code_original, rang_edition)
|
|
SELECT 'C010', 'Net à payer', 'Net à payer', 'C010', -1
|
|
WHERE 'C010' NOT IN (SELECT code_original FROM rh.t_rubriques)
|
|
;
|
|
|
|
-- Màj des situations de famille
|
|
INSERT INTO rh.t_situations_famille(code, texte, texte_court, code_original)
|
|
SELECT psa_situationfamil, psa_situationfamil, substr(psa_situationfamil,1,50), psa_situationfamil
|
|
FROM prod_cegid.salaries
|
|
WHERE 1=1
|
|
AND psa_situationfamil NOT IN (SELECT code_original FROM rh.t_situations_famille)
|
|
GROUP BY 1,2,3,4
|
|
;
|
|
|
|
-- Màj des types de contrat => cf. n½eud XML suivant.
|
|
|
|
-- Màj des statuts
|
|
INSERT INTO rh.t_statuts(code_original, code, texte, texte_court)
|
|
SELECT phs_dadscat, phs_dadscat, phs_dadscat, phs_dadscat
|
|
FROM w_histosalarie
|
|
WHERE 1=1
|
|
-- Si la table 'commun' n'est pas remontée.
|
|
AND (select count(*) = 0
|
|
from information_schema.tables
|
|
where 1=1
|
|
and table_schema = 'prod_cegid'
|
|
and table_name = 'commun')
|
|
AND phs_dadscat IS NOT NULL
|
|
AND trim(phs_dadscat) != ''
|
|
AND phs_dadscat NOT IN (SELECT code_original FROM rh.t_statuts)
|
|
AND (select valeur = 'DADSCAT' FROM rh.t_divers WHERE code = 'CEGID_STATUT')
|
|
GROUP BY 1,2,3,4
|
|
UNION
|
|
SELECT ltrim(pmi_code, '0'), ltrim(pmi_code, '0'), pmi_libelle, substr(pmi_libelle, 1, 50)
|
|
FROM prod_cegid.minimumconvent
|
|
WHERE 1=1
|
|
AND pmi_nature = 'IND'
|
|
AND ltrim(pmi_code, '0') != ''
|
|
AND ltrim(pmi_code, '0') NOT IN (SELECT code_original FROM rh.t_statuts)
|
|
AND (select valeur = 'INDICE' FROM rh.t_divers WHERE code = 'CEGID_STATUT')
|
|
GROUP BY 1,2,3,4
|
|
UNION
|
|
SELECT cc_code, cc_code, cc_libelle, substr(cc_abrege,1,50)
|
|
FROM prod_cegid.choixcod
|
|
WHERE 1=1
|
|
AND cc_type = case (select valeur from rh.t_divers where code = 'CEGID_STATUT')
|
|
when 1 then 'PAG'
|
|
when 2 then 'PST'
|
|
when 3 then 'PUN'
|
|
when 4 then 'PIW'
|
|
end -- pas de code pour 5, pas encore...
|
|
AND cc_code NOT IN (SELECT code_original FROM rh.t_statuts)
|
|
AND (select valeur in (1, 2, 3, 4) from rh.t_divers where code = 'CEGID_STATUT')
|
|
GROUP BY 1,2,3,4
|
|
;
|
|
|
|
-- Màj des types de temps de travail
|
|
INSERT INTO rh.t_types_temps_travail(code_original, code, texte, texte_court)
|
|
SELECT
|
|
phs_condemploi||phs_ttauxpartiel::float,
|
|
phs_condemploi||phs_ttauxpartiel::float,
|
|
phs_condemploi||' '||phs_ttauxpartiel::float||' %',
|
|
substr( phs_condemploi||' '||phs_ttauxpartiel::float||' %', 1, 50)
|
|
FROM w_histosalarie
|
|
WHERE 1=1
|
|
AND phs_condemploi IS NOT NULL
|
|
AND trim(phs_condemploi) != ''
|
|
AND phs_condemploi||phs_ttauxpartiel::float 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)
|
|
with niv1 as (
|
|
SELECT cc_code as code, cc_libelle as texte
|
|
FROM prod_cegid.choixcod
|
|
WHERE cc_type = 'PAG'
|
|
GROUP BY 1,2),
|
|
niv2 as (
|
|
SELECT cc_code as code, cc_libelle as texte
|
|
FROM prod_cegid.choixcod
|
|
WHERE cc_type = 'PST'
|
|
GROUP BY 1,2),
|
|
niv3 as (
|
|
SELECT cc_code as code, cc_libelle as texte
|
|
FROM prod_cegid.choixcod
|
|
WHERE cc_type = 'PUN'
|
|
GROUP BY 1,2)
|
|
select
|
|
niv1.code||'|'||niv2.code||'|'||niv3.code as code_original,
|
|
niv1.code||'|'||niv2.code||'|'||niv3.code as code,
|
|
niv1.texte||case when upper(niv2.code) not in ('0', 'O') then ' - '||niv2.texte else '' end||case when upper(niv3.code) not in ('0', 'O') then ' - '||niv3.texte else '' end as texte,
|
|
substr(niv1.texte||case when upper(niv2.code) not in ('0', 'O') then ' - '||niv2.texte else '' end||case when upper(niv3.code) not in ('0', 'O') then ' - '||niv3.texte else '' end, 1, 50) as texte_court
|
|
from niv1, niv2, niv3
|
|
where 1=1
|
|
AND niv1.code||'|'||niv2.code||'|'||niv3.code NOT IN (SELECT code_original FROM rh.t_services)
|
|
AND (select valeur = 4 from rh.t_divers where code = 'CEGID_SERVICE')
|
|
group by 1,2,3,4
|
|
UNION
|
|
SELECT cc_code, cc_code, cc_libelle, substr(cc_abrege,1,50)
|
|
FROM prod_cegid.choixcod
|
|
WHERE 1=1
|
|
AND cc_type = case (select valeur from rh.t_divers where code = 'CEGID_SERVICE')
|
|
when 1 then 'PAG'
|
|
when 2 then 'PST'
|
|
when 3 then 'PUN' end
|
|
AND cc_code NOT IN (SELECT code_original FROM rh.t_services)
|
|
AND (select valeur in (1, 2, 3) from rh.t_divers where code = 'CEGID_SERVICE')
|
|
GROUP BY 1,2,3,4
|
|
;
|
|
|
|
-- Màj des spécialités
|
|
INSERT INTO rh.t_specialites(code_original, code, texte, texte_court)
|
|
SELECT cc_code, cc_code, cc_libelle, substr(cc_abrege,1,50)
|
|
FROM prod_cegid.choixcod
|
|
WHERE 1=1
|
|
AND cc_type = 'PST'
|
|
AND cc_code NOT IN (SELECT code_original FROM rh.t_specialites)
|
|
GROUP BY 1,2,3,4
|
|
;
|
|
|
|
-- Màj des codes emploi
|
|
INSERT INTO rh.t_codes_emploi(code_original, code, texte, texte_court)
|
|
SELECT cc_code, cc_code as code_o, cc_libelle, LEFT(cc_libelle,50)
|
|
FROM prod_cegid.choixcod
|
|
WHERE 1=1
|
|
AND cc_type = 'PLE'
|
|
AND cc_code NOT IN (SELECT code_original FROM rh.t_codes_emploi)
|
|
GROUP BY 1,2,3,4
|
|
UNION
|
|
SELECT ppu_libelleemploi, ppu_libelleemploi, ppu_libelleemploi, substr(ppu_libelleemploi, 1, 50)
|
|
FROM prod_cegid.paieencours
|
|
WHERE ppu_libelleemploi NOT IN (SELECT code_original FROM rh.t_codes_emploi) AND
|
|
ppu_libelleemploi NOT IN (SELECT cc_code FROM prod_cegid.choixcod WHERE cc_type = 'PLE')
|
|
GROUP BY 1,2,3,4
|
|
;
|
|
|
|
-- @TODO: Màj des types d'horaire
|
|
|
|
-- Màj des sociétés d'interim
|
|
|
|
-- Màj des grilles
|
|
INSERT INTO rh.t_grilles(code_original, code, texte, texte_court)
|
|
SELECT ppu_coefficient, ppu_coefficient, ppu_coefficient, ppu_coefficient
|
|
FROM prod_cegid.paieencours
|
|
WHERE 1=1
|
|
AND ppu_coefficient NOT IN (SELECT code_original FROM rh.t_grilles)
|
|
AND (select valeur = 'GRILLE' FROM rh.t_divers WHERE code = 'CEGID_GRILLE')
|
|
GROUP BY 1
|
|
UNION ALL
|
|
SELECT ltrim(pmi_code, '0'), ltrim(pmi_code, '0'), pmi_libelle, substr(pmi_libelle, 1, 50)
|
|
FROM prod_cegid.minimumconvent
|
|
WHERE 1=1
|
|
AND pmi_nature = 'QUA'
|
|
AND ltrim(pmi_code, '0') NOT IN (SELECT code_original FROM rh.t_grilles)
|
|
AND (select valeur = 'QUALIFICATION' FROM rh.t_divers WHERE code = 'CEGID_GRILLE')
|
|
GROUP BY 1,2,3,4
|
|
;
|
|
|
|
-- Màj des groupes de grilles
|
|
INSERT INTO rh.t_grilles_groupes(code_original, code, texte, texte_court)
|
|
SELECT ppu_coefficient, ppu_coefficient, ppu_coefficient, ppu_coefficient
|
|
FROM prod_cegid.paieencours
|
|
WHERE 1=1
|
|
AND ppu_coefficient NOT IN (SELECT code_original FROM rh.t_grilles_groupes)
|
|
AND (select valeur = 'COEFF' FROM rh.t_divers WHERE code = 'CEGID_GRP_GRILLE')
|
|
GROUP BY 1
|
|
UNION ALL
|
|
SELECT ltrim(pmi_code, '0'), ltrim(pmi_code, '0'), pmi_libelle, substr(pmi_libelle, 1, 50)
|
|
FROM prod_cegid.minimumconvent
|
|
WHERE 1=1
|
|
AND pmi_nature = 'IND'
|
|
AND ltrim(pmi_code, '0') != ''
|
|
AND ltrim(pmi_code, '0') NOT IN (SELECT code_original FROM rh.t_grilles_groupes)
|
|
AND (select valeur = 'IND' FROM rh.t_divers WHERE code = 'CEGID_GRP_GRILLE')
|
|
GROUP BY 1,2,3,4
|
|
UNION ALL
|
|
SELECT phc_montant::int::text, phc_montant::int::text, phc_montant::int::text, phc_montant::int::text
|
|
FROM prod_cegid.histocumsal
|
|
WHERE 1=1
|
|
AND phc_cumulpaie = (SELECT valeur::int FROM rh.t_divers WHERE code = 'CEGID_GRP_GRILLE_CST')
|
|
AND phc_montant NOT IN (SELECT code_original FROM rh.t_grilles_groupes)
|
|
AND (select valeur = 'BUL' FROM rh.t_divers WHERE code = 'CEGID_GRP_GRILLE')
|
|
GROUP BY 1,2,3,4
|
|
;
|
|
|
|
-- Màj des motifs d'arret
|
|
INSERT INTO rh.t_motifs_arret(code_original, code, texte, texte_court)
|
|
SELECT
|
|
pcn_typeconge,
|
|
pcn_typeconge,
|
|
max(substring(pcn_libelle from '^(.*)[0-9]{2}/[0-9]{2}/[0-9]{2} au [0-9]{2}/[0-9]{2}/[0-9]{2}$')),
|
|
max(substr(substring(pcn_libelle from '^(.*)[0-9]{2}/[0-9]{2}/[0-9]{2} au [0-9]{2}/[0-9]{2}/[0-9]{2}$'),1,50))
|
|
FROM prod_cegid.absencesalarie
|
|
WHERE 1=1
|
|
AND pcn_typemvt = 'ABS'
|
|
AND pcn_mvtduplique != 'X'
|
|
AND pcn_typeconge NOT IN (SELECT code_original FROM rh.t_motifs_arret)
|
|
GROUP BY 1,2
|
|
;
|
|
|
|
-- @TODO: Màj des précisions du motif d'arrêt
|
|
|
|
-- @TODO: Màj des motifs de visite médicale
|
|
|
|
-- @TODO: Màj des circonstances d'accident du travail
|
|
|
|
-- @TODO: Màj des lieux d'accident du travail
|
|
|
|
-- @TODO: Màj de la nature de l'accident du travail
|
|
|
|
-- @TODO: Màj des sièges d'accident du travail
|
|
|
|
-- @TODO: Màj des listes de formations
|
|
|
|
-- Màj des sections analytiques compta
|
|
INSERT INTO rh.t_sections_analytiques(code_original, code, texte, texte_court)
|
|
SELECT s_section, s_section, MAX(s_libelle), MAX(substr(s_abrege,1,50))
|
|
FROM prod_cegid.section
|
|
WHERE s_section NOT IN (SELECT code_original FROM rh.t_sections_analytiques)
|
|
GROUP BY 1,2
|
|
;
|
|
|
|
-- Màj des sections analytiques paie
|
|
|
|
]]></sqlcmd>
|
|
</NODE>
|
|
<NODE label="Mise à jour des informations permanentes (comptes)">
|
|
<condition><![CDATA[
|
|
|
|
-- Si la table
|
|
select count(*) > 0
|
|
from information_schema.tables
|
|
where 1=1
|
|
and table_schema = 'prod_cegid'
|
|
and table_name = 'guideecrpaie'
|
|
;
|
|
|
|
]]></condition>
|
|
<sqlcmd><![CDATA[
|
|
|
|
-- Màj des comptes comtpables.
|
|
INSERT INTO rh.t_compte(code_original, code, texte, texte_court)
|
|
SELECT pgc_general, pgc_general, max(pgc_libelle), substr(max(pgc_libelle), 1, 50)
|
|
FROM prod_cegid.guideecrpaie
|
|
WHERE pgc_general NOT IN (SELECT code_original FROM rh.t_compte)
|
|
group by 1,2
|
|
;
|
|
|
|
]]></sqlcmd>
|
|
</NODE>
|
|
<NODE label="Mise à jour des informations permanentes (spécifique 243)">
|
|
<condition><![CDATA[
|
|
|
|
-- Si la table commun n'est pas importée, il s'agit du 243.
|
|
select current_database() = 'icti_243'
|
|
;
|
|
|
|
]]></condition>
|
|
<sqlcmd><![CDATA[
|
|
|
|
-- Màj des types de contrat
|
|
INSERT INTO rh.t_types_contrat(code, texte, texte_court, code_original)
|
|
SELECT cc_code, cc_libelle, substr(cc_abrege,1,50), cc_code
|
|
FROM prod_cegid.choixcod
|
|
WHERE 1=1
|
|
AND cc_type = 'PAG'
|
|
AND cc_code NOT IN (SELECT code_original FROM rh.t_types_contrat)
|
|
GROUP BY 1,2,3,4
|
|
;
|
|
|
|
-- Màj des motifs de fin de contrat (ancienne méthode).
|
|
INSERT INTO rh.t_motifs_fin_contrat(code, code_original, texte, texte_court)
|
|
SELECT trim(psa_motifsortie), trim(psa_motifsortie), trim(psa_motifsortie), trim(substr(psa_motifsortie,1,50))
|
|
FROM prod_cegid.salaries
|
|
WHERE psa_motifsortie NOT IN (SELECT code_original FROM rh.t_motifs_fin_contrat)
|
|
GROUP BY 1,2,3,4
|
|
;
|
|
|
|
]]></sqlcmd>
|
|
</NODE>
|
|
<NODE label="Mise à jour des informations permanentes (nouvelle méthode)">
|
|
<condition><![CDATA[
|
|
|
|
-- Si la table commun est importée, il s'agit de la nouvelle méthode d'import.
|
|
select current_database() != 'icti_243'
|
|
;
|
|
|
|
]]></condition>
|
|
<sqlcmd><![CDATA[
|
|
|
|
-- Màj des types de contrat
|
|
INSERT INTO rh.t_types_contrat(code, texte, texte_court, code_original)
|
|
SELECT co_code, co_libelle, substr(co_abrege,1,50), co_code
|
|
FROM prod_cegid.commun
|
|
WHERE 1=1
|
|
AND co_type = 'PCT'
|
|
AND co_code NOT IN (SELECT code_original FROM rh.t_types_contrat)
|
|
GROUP BY 1,2,3,4
|
|
;
|
|
|
|
-- Màj des motifs de fin de contrat (nouvelle méthode).
|
|
INSERT INTO rh.t_motifs_fin_contrat(code, code_original, texte, texte_court)
|
|
SELECT co_code, co_code, max(co_libre), max(substr(co_libre, 1, 50))
|
|
FROM prod_cegid.commun
|
|
WHERE 1=1
|
|
AND co_type = 'PNP'
|
|
AND co_code NOT IN (SELECT code_original FROM rh.t_motifs_fin_contrat)
|
|
AND (select valeur = '0' FROM rh.t_divers WHERE code = 'CEGID_MOTIF_FIN')
|
|
GROUP BY 1,2
|
|
UNION
|
|
SELECT pms_assediccor, pms_assediccor, max(pms_libelle), max(substr(pms_libelle, 1, 50))
|
|
FROM prod_cegid.motifsortiepay
|
|
WHERE 1=1
|
|
AND pms_assediccor NOT IN (SELECT code_original FROM rh.t_motifs_fin_contrat)
|
|
AND pms_assediccor != '00'
|
|
AND (select valeur = '1' FROM rh.t_divers WHERE code = 'CEGID_MOTIF_FIN')
|
|
GROUP BY 1,2
|
|
UNION
|
|
SELECT pms_code, pms_code, max(pms_libelle), max(substr(pms_libelle, 1, 50))
|
|
FROM prod_cegid.motifsortiepay
|
|
WHERE 1=1
|
|
AND pms_code NOT IN (SELECT code_original FROM rh.t_motifs_fin_contrat)
|
|
AND (select valeur = '2' FROM rh.t_divers WHERE code = 'CEGID_MOTIF_FIN')
|
|
GROUP BY 1,2
|
|
;
|
|
|
|
-- Màj des statuts
|
|
INSERT INTO rh.t_statuts(code_original, code, texte, texte_court)
|
|
SELECT co_code, co_code, coalesce(nullif(trim(co_libre), ''), co_libelle), substr(coalesce(nullif(trim(co_libre), ''), co_libelle), 1, 50)
|
|
FROM prod_cegid.commun
|
|
WHERE 1=1
|
|
AND co_type = 'PDC'
|
|
AND co_code NOT IN (SELECT code_original FROM rh.t_statuts)
|
|
AND (select valeur = 'DADSCAT' FROM rh.t_divers WHERE code = 'CEGID_STATUT')
|
|
GROUP BY 1,2,3,4
|
|
UNION
|
|
SELECT co_code, co_code, coalesce(nullif(trim(co_libre), ''), co_libelle), substr(coalesce(nullif(trim(co_libre), ''), co_libelle), 1, 50)
|
|
FROM prod_cegid.commun
|
|
WHERE 1=1
|
|
AND co_type = 'PDP'
|
|
AND co_code NOT IN (SELECT code_original FROM rh.t_statuts)
|
|
AND (select valeur = 'DADSPROF' FROM rh.t_divers WHERE code = 'CEGID_STATUT')
|
|
GROUP BY 1,2,3,4
|
|
;
|
|
|
|
]]></sqlcmd>
|
|
</NODE>
|
|
<NODE label="Mise à jour des informations permanentes">
|
|
<sqlcmd><![CDATA[
|
|
|
|
-- Màj des types de contrats pour ne jamais "oublier" aucun code (CCD/CDD).
|
|
INSERT INTO rh.t_types_contrat(code, texte, texte_court, code_original)
|
|
SELECT pci_typecontrat, pci_typecontrat, substr(pci_typecontrat,1,50), pci_typecontrat
|
|
FROM w_contrattravail
|
|
WHERE pci_typecontrat NOT IN (SELECT code_original FROM rh.t_types_contrat)
|
|
GROUP BY 1,2,3,4
|
|
;
|
|
|
|
]]></sqlcmd>
|
|
</NODE>
|
|
</NODE>
|
|
<NODE name="PROD" label="RECUPERATION DES DONNEES DE PRODUCTION">
|
|
<NODE label="Chiffrier">
|
|
<sqlcmd><![CDATA[
|
|
|
|
TRUNCATE rh.p_chiffrier_production
|
|
;
|
|
|
|
INSERT INTO rh.p_chiffrier_production (entreprise_id, etablissement_id, mois, nombre_salaries, montant_brut, nombre_heures)
|
|
SELECT
|
|
t_entreprises.oid,
|
|
t_etablissements.oid,
|
|
to_char(ppu_datefin,'YYYYMM')::numeric,
|
|
count(DISTINCT ppu_salarie),
|
|
sum(ppu_cbrut)::numeric,
|
|
sum(heures_payees)::numeric
|
|
FROM prod_cegid.paieencours
|
|
JOIN ( -- Cette jointure permet de compter correctement le nombre de salarié.
|
|
SELECT phb_salarie, phb_datefin
|
|
FROM prod_cegid.histobulletin
|
|
WHERE 1=1
|
|
-- @WHERE_1 -- Même WHERE que pour le peuplement des bulletins de paie.
|
|
AND phb_imprimable = 'X'
|
|
AND (1!=1
|
|
OR phb_mtrem <> 0
|
|
OR phb_mtsalarial <> 0
|
|
OR phb_mtpatronal <> 0
|
|
)
|
|
AND phb_datefin::date - phb_datedebut::date < 31 -- pas les bulletins de paie sur plus d'un mois (lève le matricule 151)
|
|
-- date_part('month', phb_datefin) != date_part('month', phb_datedebut) -- (lève les matricules 151 et 1217)
|
|
--
|
|
GROUP BY 1,2
|
|
) AS subq ON 1=1
|
|
AND subq.phb_salarie = ppu_salarie
|
|
AND subq.phb_datefin = ppu_datefin
|
|
LEFT JOIN ( -- Cette jointure permet de compter le bon nombre d'heures payées paramétré dans t_rubriques (code_calcul = 1).
|
|
SELECT
|
|
phc_salarie,
|
|
phc_datefin,
|
|
sum(phc_montant)::numeric AS heures_payees
|
|
FROM prod_cegid.histocumsal
|
|
WHERE phc_cumulpaie = (select substr(code_original, 3, 2)::int from rh.t_rubriques where substr(code_original, 1, 2) = 'C0' and code_calcul = 1)
|
|
GROUP BY 1,2
|
|
) AS subq2 ON 1=1
|
|
AND subq2.phc_salarie = subq.phb_salarie
|
|
AND subq2.phc_datefin = subq.phb_datefin
|
|
JOIN rh.t_etablissements ON t_etablissements.code_original = ppu_etablissement
|
|
JOIN rh.t_entreprises ON t_entreprises.oid = t_etablissements.entreprise_id
|
|
WHERE 1=1
|
|
AND date_part('year', ppu_datefin) >= 2009
|
|
GROUP BY 1,2,3
|
|
;
|
|
|
|
]]></sqlcmd>
|
|
</NODE>
|
|
<NODE label="Pré-traitements">
|
|
<sqlcmd><![CDATA[
|
|
|
|
-- Création d'une table de paies non chevauchantes (retrait des bulletins complémentaires chevauchants)
|
|
DROP TABLE IF EXISTS w_paieencours_nc -- _nc pour "Non Chevauchantes"
|
|
;
|
|
|
|
CREATE TEMP TABLE w_paieencours_nc AS
|
|
SELECT
|
|
*,
|
|
chr(1)||'*' as coefficient
|
|
FROM w_paieencours
|
|
--WHERE ppu_bulcompl != 'X'
|
|
;
|
|
|
|
DELETE FROM w_paieencours_nc
|
|
USING (
|
|
select t1.ppu_salarie, t1.date_debut, t1.date_fin
|
|
from w_paieencours AS t1
|
|
join w_paieencours as t2 on 1=1
|
|
and t1.ppu_salarie = t2.ppu_salarie
|
|
and base.cti_overlaps(t1.date_debut, t1.date_fin, t2.date_debut, t2.date_fin)
|
|
and (t1.date_debut||t1.date_fin) != (t2.date_debut||t2.date_fin)
|
|
and t1.ppu_bulcompl = 'X'
|
|
group by 1,2,3
|
|
) AS subq
|
|
WHERE 1=1
|
|
AND w_paieencours_nc.ppu_salarie = subq.ppu_salarie
|
|
AND w_paieencours_nc.date_debut = subq.date_debut
|
|
AND w_paieencours_nc.date_fin = subq.date_fin
|
|
;
|
|
|
|
UPDATE w_paieencours_nc SET
|
|
coefficient = phc_montant::int::text
|
|
FROM prod_cegid.histocumsal
|
|
WHERE 1=1
|
|
and phc_salarie = ppu_salarie
|
|
and phc_datedebut = ppu_datedebut
|
|
and phc_datefin = ppu_datefin
|
|
and phc_cumulpaie = (SELECT valeur::int FROM rh.t_divers WHERE code = 'CEGID_GRP_GRILLE_CST')
|
|
;
|
|
|
|
WITH services as (
|
|
SELECT
|
|
CASE (SELECT valeur::int FROM rh.t_divers WHERE code = 'CEGID_SERVICE')
|
|
WHEN 1 THEN ppu_travailn1
|
|
WHEN 2 THEN ppu_travailn2
|
|
WHEN 3 THEN ppu_travailn3
|
|
WHEN 4 THEN ppu_travailn1||'|'||ppu_travailn2||'|'||ppu_travailn3 -- le champ 4 existe (cf. type de contrat qqes lignes plus bas) ! : posera pb à PCBS.
|
|
ELSE ppu_travailn3 END as code
|
|
FROM w_paieencours_nc
|
|
GROUP BY 1
|
|
)
|
|
INSERT INTO rh.t_services(code_original, code, texte, texte_court)
|
|
SELECT code, code, code, code
|
|
FROM services
|
|
WHERE code NOT IN (SELECT code_original FROM rh.t_services)
|
|
;
|
|
|
|
WITH types_contrat as (
|
|
SELECT
|
|
CASE (SELECT valeur::int FROM rh.t_divers WHERE code = 'CEGID_TYPE_CONTRAT')
|
|
WHEN 1 THEN ppu_travailn1
|
|
WHEN 2 THEN ppu_travailn2
|
|
WHEN 3 THEN ppu_travailn3
|
|
WHEN 4 THEN ppu_travailn4 -- le champ 4 existe !
|
|
ELSE ppu_travailn1 END as code
|
|
FROM w_paieencours_nc
|
|
GROUP BY 1
|
|
)
|
|
INSERT INTO rh.t_types_contrat(code_original, code, texte, texte_court)
|
|
SELECT code, code, code, code
|
|
FROM types_contrat
|
|
WHERE code NOT IN (SELECT code_original FROM rh.t_types_contrat)
|
|
;
|
|
|
|
-- Création d'une table identifiant le mois de paie en-cours.
|
|
DROP TABLE IF EXISTS w_paie_est_encours
|
|
;
|
|
|
|
CREATE TEMP TABLE w_paie_est_encours AS
|
|
select
|
|
to_char(ppu_datedebut, 'YYYYMM') AS mois,
|
|
max(
|
|
case when 1=1
|
|
AND ppu_topgenecr != 'X'
|
|
AND ppu_topcloture != 'X'
|
|
AND ppu_datedebut >= '2012-01-01'::date
|
|
then 1
|
|
else 0
|
|
end)
|
|
as est_en_cours
|
|
from prod_cegid.paieencours
|
|
where ppu_bulcompl != 'X'
|
|
group by 1
|
|
;
|
|
|
|
-- Cas où plus d'un mois ont été identifiés comme en cours.
|
|
UPDATE w_paie_est_encours
|
|
SET est_en_cours = 0
|
|
WHERE 1=1
|
|
AND (SELECT count(est_en_cours) FROM w_paie_est_encours WHERE est_en_cours = 1) > 1
|
|
AND est_en_cours = 1
|
|
AND mois != (SELECT max(mois) FROM w_paie_est_encours WHERE est_en_cours = 1)
|
|
;
|
|
|
|
-- Cas où pas de mois en cours identifié.
|
|
insert into w_paie_est_encours
|
|
SELECT
|
|
to_char(max(to_date(mois, 'YYYYMM')) + '1 month'::interval, 'YYYYMM'),
|
|
1
|
|
FROM w_paie_est_encours
|
|
WHERE (SELECT max(est_en_cours) FROM w_paie_est_encours) = 0
|
|
group by 2
|
|
;
|
|
|
|
DROP TABLE IF EXISTS w_ventana
|
|
;
|
|
|
|
CREATE TEMP TABLE w_ventana AS
|
|
SELECT
|
|
split_part(yva_identifiant,';',1) as matricule,
|
|
to_char(to_date(split_part(yva_identifiant,';',2), 'DDMMYYYY'), 'YYYYMM') as mois,
|
|
to_date(split_part(yva_identifiant,';',2), 'DDMMYYYY') as date_debut,
|
|
to_date(split_part(yva_identifiant,';',3), 'DDMMYYYY') as date_fin,
|
|
yva_section as section,
|
|
sum(yva_pourcentage)/100.0 as ratio
|
|
FROM prod_cegid.ventana
|
|
JOIN w_paieencours_nc ON 1=1 -- permet de ne retenir que les ventilations analytiques associées à une paye (exclu les ventilations chevauchantes; ex :1579 du 1er au 25 novembre 2013)
|
|
AND w_paieencours_nc.ppu_salarie = split_part(yva_identifiant,';',1)
|
|
AND w_paieencours_nc.date_debut = to_date(split_part(yva_identifiant,';',2), 'DDMMYYYY')
|
|
AND w_paieencours_nc.date_fin = to_date(split_part(yva_identifiant,';',3), 'DDMMYYYY')
|
|
WHERE 1=1
|
|
AND yva_axe = 'A1'
|
|
AND split_part(yva_identifiant,';',4) = 'COT'
|
|
AND yva_pourcentage > 0
|
|
GROUP BY 1,2,3,4,5
|
|
;
|
|
|
|
-- Clef ventilation_id : matricule, mois, section
|
|
DROP TABLE IF EXISTS w_ventilation
|
|
;
|
|
|
|
CREATE TEMP TABLE w_ventilation AS
|
|
select
|
|
w_ventana.mois,
|
|
greatest(w_ventana.date_debut, w_contrattravail_mois.date_debut_mv) AS date_debut,
|
|
least(w_ventana.date_fin, w_contrattravail_mois.date_fin_mv) AS date_fin,
|
|
w_ventana.matricule,
|
|
w_ventana.section,
|
|
0 AS ventilation_id,
|
|
ratio,
|
|
numero_contrat,
|
|
0 AS est_hors_periode
|
|
FROM w_ventana
|
|
LEFT JOIN w_contrattravail_mois on 1=1
|
|
AND w_contrattravail_mois.pci_salarie = w_ventana.matricule
|
|
--AND w_contrattravail_mois.date_debut_mv = w_ventana.date_debut
|
|
--AND w_contrattravail_mois.date_fin_mv = w_ventana.date_fin
|
|
AND base.cti_overlaps(date_debut_mv, date_fin_mv, w_ventana.date_debut, w_ventana.date_fin)
|
|
WHERE (SELECT valeur = '1' FROM rh.t_divers WHERE code = 'OPT_VENT_PAIE')
|
|
group by 1,2,3,4,5,6,7,8,9
|
|
;
|
|
|
|
DROP SEQUENCE IF EXISTS w_ventilation_seq
|
|
;
|
|
|
|
CREATE TEMP SEQUENCE w_ventilation_seq
|
|
;
|
|
|
|
UPDATE w_ventilation
|
|
SET ventilation_id = nextval('w_ventilation_seq')
|
|
;
|
|
|
|
-- Association des ventilations "hors période" au contrat plus récent (on prend le contrat précédent la ventilation).
|
|
UPDATE w_ventilation
|
|
SET
|
|
numero_contrat = subq.numero_contrat,
|
|
est_hors_periode = 1
|
|
FROM (
|
|
select
|
|
ventilation_id,
|
|
w_contrattravail.numero_contrat
|
|
FROM w_ventilation
|
|
left join w_contrattravail on w_contrattravail.pci_salarie = w_ventilation.matricule
|
|
where 1=1
|
|
AND w_ventilation.numero_contrat is null
|
|
AND w_ventilation.date_debut > w_contrattravail.date_fin
|
|
GROUP BY 1,2
|
|
) AS subq
|
|
WHERE w_ventilation.ventilation_id = subq.ventilation_id
|
|
;
|
|
|
|
-- Association des ventilations "hors période" au contrat plus récent (on prend le contrat suivant la ventilation).
|
|
UPDATE w_ventilation
|
|
SET
|
|
numero_contrat = subq.numero_contrat,
|
|
est_hors_periode = 1
|
|
FROM (
|
|
select
|
|
ventilation_id,
|
|
w_contrattravail.numero_contrat
|
|
FROM w_ventilation
|
|
left join w_contrattravail on w_contrattravail.pci_salarie = w_ventilation.matricule
|
|
where 1=1
|
|
AND w_ventilation.numero_contrat is null
|
|
AND w_ventilation.date_debut < w_contrattravail.date_fin
|
|
GROUP BY 1,2
|
|
) AS subq
|
|
WHERE w_ventilation.ventilation_id = subq.ventilation_id
|
|
;
|
|
|
|
-- Création d'une table temporaire ventilée mensuellement des évenements salariés.
|
|
DROP TABLE IF EXISTS w_salarie_mois
|
|
;
|
|
|
|
CREATE TEMP TABLE w_salarie_mois AS
|
|
SELECT
|
|
ppu_etablissement AS eta,
|
|
ppu_salarie AS matricule,
|
|
cnt.numero_contrat,
|
|
greatest(cnt.date_debut,pai.date_debut) AS date_debut,
|
|
least(cnt.date_fin,pai.date_fin) AS date_fin,
|
|
cnt.date_debut AS datedebutcontrat,
|
|
cnt.date_fin AS datefincontrat,
|
|
pai.ppu_datedebut::date AS datepaiedebut,
|
|
pai.ppu_datefin::date AS datepaiefin,
|
|
CASE WHEN pci_salarie IS NULL THEN 1 ELSE 0 END AS est_hors_periode,
|
|
coalesce(lower(ppu_codeemploi::text), chr(1)||'*') AS categorie_socio_professionnelle_code_original,
|
|
coalesce(upper(ppu_libelleemploi::text), chr(1)||'*') AS code_emploi_code_original,
|
|
coalesce(CASE WHEN (SELECT valeur = 'GRILLE' FROM rh.t_divers WHERE code = 'CEGID_GRILLE') THEN ppu_coefficient::text ELSE ltrim(ppu_qualification, '0') END, chr(1)||'*') AS grille_code_original,
|
|
coalesce(ppu_indice::text, chr(1)||'*') AS ppu_indice,
|
|
coalesce(ppu_coefficient::text, chr(1)||'*') AS ppu_coefficient,
|
|
coalesce(ppu_travailn1::text, chr(1)||'*') AS ppu_travailn1,
|
|
coalesce(ppu_travailn2::text, chr(1)||'*') AS ppu_travailn2,
|
|
coalesce(ppu_travailn3::text, chr(1)||'*') AS ppu_travailn3,
|
|
coalesce(ppu_travailn4::text, chr(1)||'*') AS ppu_travailn4,
|
|
coalesce(coefficient, chr(1)||'*') AS coefficient,
|
|
coalesce(ppu_codestat, chr(1)||'*') AS groupe_cotisant_code_original,
|
|
coalesce(CASE WHEN (SELECT valeur = 'QUALIFICATION' FROM rh.t_divers WHERE code = 'CEGID_QUALIFICATION') THEN ltrim(ppu_qualification, '0') ELSE upper(ppu_libelleemploi::text) END, chr(1)||'*') AS qualification_code_original,
|
|
coalesce(
|
|
CASE (SELECT valeur::int FROM rh.t_divers WHERE code = 'CEGID_SERVICE')
|
|
WHEN 1 THEN ppu_travailn1
|
|
WHEN 2 THEN ppu_travailn2
|
|
WHEN 3 THEN ppu_travailn3
|
|
WHEN 4 THEN ppu_travailn1||'|'||ppu_travailn2||'|'||ppu_travailn3 -- le champ 4 existe (cf. type de contrat qqes lignes plus bas) ! : posera pb à PCBS.
|
|
ELSE ppu_travailn3 END,
|
|
chr(1)||'*') AS service_code_original,
|
|
coalesce(ppu_travailn2, chr(1)||'*') AS specialite_code_original,
|
|
coalesce(pci_typecontrat,
|
|
CASE (SELECT valeur::int FROM rh.t_divers WHERE code = 'CEGID_TYPE_CONTRAT')
|
|
WHEN 1 THEN ppu_travailn1
|
|
WHEN 2 THEN ppu_travailn2
|
|
WHEN 3 THEN ppu_travailn3
|
|
WHEN 4 THEN ppu_travailn4 -- le champ 4 existe !
|
|
ELSE ppu_travailn1 END,
|
|
chr(1)||'*') AS type_contrat_code_original,
|
|
cnt.pci_motifsortie as motif_fin_code_original
|
|
FROM w_paieencours_nc AS pai
|
|
LEFT JOIN w_contrattravail AS cnt ON 1=1
|
|
AND pai.ppu_salarie = cnt.pci_salarie
|
|
AND base.cti_overlaps(pai.date_debut, pai.date_fin, cnt.date_debut, cnt.date_fin)
|
|
;
|
|
|
|
-- Mise à jour des contrat hors_période et non renseignés :
|
|
-- ex : 2 évènements : 201108 (couvert par CDD n°5) et 201109 (non couvert par contrat)
|
|
-- => 201109 sera renseigné avec le CDD n°5.
|
|
UPDATE w_salarie_mois
|
|
SET numero_contrat = subq.numero_contrat,
|
|
datedebutcontrat = subq.datedebutcontrat,
|
|
datefincontrat = subq.datefincontrat
|
|
FROM (
|
|
select
|
|
w_contrattravail.pci_salarie AS matricule,
|
|
max(w_contrattravail.numero_contrat) AS numero_contrat,
|
|
max(w_contrattravail.date_debut) AS datedebutcontrat,
|
|
max(w_contrattravail.date_fin) AS datefincontrat,
|
|
datepaiedebut,
|
|
datepaiefin
|
|
from w_contrattravail
|
|
join (
|
|
select matricule, datepaiedebut, datepaiefin
|
|
from w_salarie_mois
|
|
where est_hors_periode = 1
|
|
) as subq1 on subq1.matricule = w_contrattravail.pci_salarie
|
|
where 1=1
|
|
and w_contrattravail.date_fin < subq1.datepaiedebut
|
|
group by 1,5,6
|
|
) AS subq
|
|
WHERE 1=1
|
|
AND w_salarie_mois.matricule = subq.matricule
|
|
AND w_salarie_mois.datepaiedebut = subq.datepaiedebut
|
|
AND w_salarie_mois.datepaiefin = subq.datepaiefin
|
|
AND w_salarie_mois.est_hors_periode = 1
|
|
;
|
|
|
|
-- Mise à jour des contrats restants non renseignés :
|
|
-- ex : 2 évènements : 201108 (non couvert par contrat) et 201109 (couvert par CDD n°1)
|
|
-- => 201108 sera renseigné avec le CDD n°1.
|
|
UPDATE w_salarie_mois
|
|
SET numero_contrat = subq.numero_contrat,
|
|
datedebutcontrat = subq.datedebutcontrat,
|
|
datefincontrat = subq.datefincontrat
|
|
FROM (
|
|
select
|
|
w_contrattravail.pci_salarie AS matricule,
|
|
min(w_contrattravail.numero_contrat) AS numero_contrat,
|
|
min(w_contrattravail.date_debut) AS datedebutcontrat,
|
|
min(w_contrattravail.date_fin) AS datefincontrat,
|
|
datepaiedebut,
|
|
datepaiefin
|
|
from w_contrattravail
|
|
join (
|
|
select matricule, datepaiedebut, datepaiefin
|
|
from w_salarie_mois
|
|
where est_hors_periode = 1
|
|
) as subq1 on subq1.matricule = w_contrattravail.pci_salarie
|
|
where 1=1
|
|
and w_contrattravail.date_fin > subq1.datepaiedebut
|
|
group by 1,5,6
|
|
) AS subq
|
|
WHERE 1=1
|
|
AND w_salarie_mois.matricule = subq.matricule
|
|
AND w_salarie_mois.datepaiedebut = subq.datepaiedebut
|
|
AND w_salarie_mois.datepaiefin = subq.datepaiefin
|
|
AND w_salarie_mois.est_hors_periode = 1
|
|
;
|
|
|
|
]]></sqlcmd>
|
|
</NODE>
|
|
<NODE label="Pre-traitement des Profils">
|
|
<sqlcmd><![CDATA[
|
|
|
|
-- Création d'une table temp de profils (axé sur les contrats)
|
|
DROP TABLE IF EXISTS w_profils
|
|
;
|
|
|
|
CREATE TEMP TABLE w_profils AS
|
|
SELECT
|
|
0 AS profil_id, -- Identifiant CTI du profil CTI
|
|
0 AS last_profil, -- Profil le + récent = 1, sinon à 0
|
|
-- Cléfs naturelles permettant le matching du profil CTI au données Cegid
|
|
sal.eta,
|
|
sal.matricule,
|
|
sal.numero_contrat,
|
|
min(greatest(sal.date_debut,hst.date_debut,vnt.date_debut)) AS date_debut,
|
|
max(least(sal.date_fin,hst.date_fin,vnt.date_fin)) AS date_fin,
|
|
sal.datedebutcontrat,
|
|
sal.datefincontrat,
|
|
sal.datepaiedebut::date,
|
|
sal.datepaiefin::date,
|
|
coalesce(vnt.ventilation_id, 0) AS ventilation_id,
|
|
sal.est_hors_periode,
|
|
-- Données du Profil CTI
|
|
coalesce(sal.categorie_socio_professionnelle_code_original, chr(1)||'*') as categorie_socio_professionnelle_code_original,
|
|
coalesce(sal.code_emploi_code_original, chr(1)||'*') as code_emploi_code_original,
|
|
coalesce(sal.grille_code_original, chr(1)||'*') as grille_code_original,
|
|
coalesce(CASE (SELECT valeur FROM rh.t_divers WHERE code = 'CEGID_GRP_GRILLE')
|
|
WHEN 'COEFF' THEN sal.ppu_coefficient
|
|
WHEN 'IND' THEN hst.phs_dadsprof
|
|
WHEN 'BUL' THEN coefficient
|
|
ELSE sal.ppu_indice
|
|
END, chr(1)||'*') AS grille_groupe_code_original,
|
|
coalesce(sal.groupe_cotisant_code_original, chr(1)||'*') as groupe_cotisant_code_original,
|
|
chr(1)||'*' AS motif_debut_code_original,
|
|
coalesce(case when sal.datefincontrat = '2099-12-31'::date then 'CTI_CNT_EC' else sal.motif_fin_code_original end, chr(1)||'*') as motif_fin_code_original,
|
|
coalesce(sal.qualification_code_original, chr(1)||'*') as qualification_code_original,
|
|
coalesce(greatest(vnt.section, chr(1)||'*'), chr(1)||'*') AS section_analytique_code_original,
|
|
chr(1)||'*' AS section_analytique_paie_code_original,
|
|
coalesce(sal.service_code_original, chr(1)||'*') as service_code_original,
|
|
chr(1)||'*' AS societe_interim_code_original,
|
|
coalesce(sal.specialite_code_original, chr(1)||'*') as specialite_code_original,
|
|
coalesce(CASE (SELECT valeur FROM rh.t_divers WHERE code = 'CEGID_STATUT')
|
|
WHEN 'INDICE' THEN sal.ppu_indice
|
|
WHEN 'DADSPROF' THEN hst.phs_dadsprof
|
|
WHEN '1' THEN sal.ppu_travailn1
|
|
WHEN '2' THEN sal.ppu_travailn2
|
|
WHEN '3' THEN sal.ppu_travailn3
|
|
WHEN '4' THEN sal.ppu_travailn4
|
|
ELSE greatest(hst.phs_dadscat, chr(1)||'*') -- par défaut 'DADSCAT'
|
|
END, chr(1)||'*') AS statut_code_original, -- histosalarie
|
|
coalesce(sal.type_contrat_code_original, chr(1)||'*') as type_contrat_code_original,
|
|
chr(1)||'*' AS type_horaire_code_original,
|
|
coalesce(greatest(hst.phs_condemploi||phs_ttauxpartiel::float, chr(1)||'*'), chr(1)||'*') as type_temps_travail_code_original, -- histosalarie
|
|
-- Champs dédiés au public.
|
|
chr(1)||'*' AS unite_fonctionnelle_code_original,
|
|
chr(1)||'*' AS categorie_conge_code_original,
|
|
chr(1)||'*' AS compte_salarie_code_original,
|
|
chr(1)||'*' AS commission_paritaire_code_original,
|
|
chr(1)||'*' AS lettre_budgetaire_code_original,
|
|
chr(1)||'*' AS cadre_emploi_code_original,
|
|
chr(1)||'*' AS filiere_code_original,
|
|
chr(1)||'*' AS categorie_statutaire_code_original
|
|
FROM w_salarie_mois AS sal
|
|
LEFT JOIN w_histosalarie AS hst ON 1=1
|
|
AND hst.phs_salarie = sal.matricule
|
|
AND base.cti_overlaps(hst.date_debut, hst.date_fin, sal.date_debut, sal.date_fin)
|
|
LEFT JOIN w_ventilation AS vnt ON 1=1
|
|
AND vnt.matricule = sal.matricule
|
|
AND base.cti_overlaps(vnt.date_debut, vnt.date_fin, sal.date_debut, sal.date_fin)
|
|
--AND vnt.date_debut = greatest(sal.date_debut,hst.date_debut)
|
|
--AND vnt.date_fin = least(sal.date_fin,hst.date_fin)
|
|
WHERE 1=1
|
|
GROUP BY 1,2,3,4,5,8,9,10,11,12,13,14,15,16,17,18,19,20,21,22,23,24,25,26,27,28,29,30
|
|
;
|
|
|
|
-- Marquage du profil le plus récent pour chaque salarié
|
|
UPDATE w_profils
|
|
SET last_profil = 1
|
|
FROM
|
|
(
|
|
SELECT
|
|
matricule,
|
|
max(datepaiefin) AS datepaiefin,
|
|
max(numero_contrat) AS numero_contrat
|
|
FROM w_profils
|
|
GROUP BY 1
|
|
) AS subq
|
|
WHERE 1=1
|
|
AND w_profils.matricule = subq.matricule
|
|
AND w_profils.datepaiefin = subq.datepaiefin
|
|
AND w_profils.numero_contrat = subq.numero_contrat
|
|
;
|
|
|
|
-- Mise à jour du motif d'entrée du salarié dans l'établissement (sur son premier contrat uniquement)
|
|
UPDATE w_profils
|
|
SET motif_debut_code_original = trim(salaries.psa_motifentree)
|
|
FROM prod_cegid.salaries
|
|
JOIN
|
|
(
|
|
SELECT pci_salarie, (MIN(ARRAY[date_debut::text,numero_contrat]))[2] AS numero_contrat_debut
|
|
FROM w_contrattravail
|
|
GROUP BY 1
|
|
) subview ON psa_salarie = pci_salarie
|
|
WHERE 1=1
|
|
AND salaries.psa_salarie = w_profils.matricule
|
|
AND subview.numero_contrat_debut = w_profils.numero_contrat
|
|
AND length(trim(salaries.psa_motifentree)) > 0
|
|
AND salaries.psa_motifentree IS NOT NULL
|
|
AND salaries.psa_salarie = w_profils.matricule
|
|
;
|
|
|
|
-- Mise à jour du motif de sortie du salarié de l'établissement (sur son dernier contrat uniquement)
|
|
UPDATE w_profils
|
|
SET motif_fin_code_original = trim(salaries.psa_motifsortie)
|
|
FROM prod_cegid.salaries
|
|
JOIN
|
|
(
|
|
SELECT pci_salarie, (MAX(ARRAY[date_debut::text,numero_contrat]))[2] AS numero_contrat_fin
|
|
FROM w_contrattravail
|
|
GROUP BY 1
|
|
) subview ON psa_salarie = pci_salarie
|
|
WHERE 1=1
|
|
AND (select valeur != '2' FROM rh.t_divers WHERE code = 'CEGID_MOTIF_FIN')
|
|
AND salaries.psa_salarie = w_profils.matricule
|
|
AND subview.numero_contrat_fin = w_profils.numero_contrat
|
|
AND length(trim(salaries.psa_motifsortie)) > 0
|
|
AND salaries.psa_motifsortie IS NOT NULL
|
|
;
|
|
|
|
]]></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,
|
|
psa_libelle AS nom,
|
|
psa_prenom AS prenom,
|
|
psa_datenaissance::date AS date_naissance,
|
|
psa_sexe AS sexe,
|
|
psa_salarie AS matricule,
|
|
psa_salarie AS code,
|
|
psa_salarie AS code_original,
|
|
coalesce(t_entreprises.oid,0) AS entreprise_id,
|
|
coalesce(t_nationalites.oid,0) AS nationalite_id,
|
|
coalesce(t_codes_postaux.oid,0) AS code_postal_id,
|
|
psa_nomjf AS nom_naissance,
|
|
coalesce(t_situations_famille.oid,0) AS situation_famille_id,
|
|
coalesce((max(array[extract(EPOCH FROM w_profils.date_fin)::bigint, w_profils.profil_id]))[2], 0) AS profil_id, -- dernier profil salarié.
|
|
to_timestamp(coalesce((max(array[extract(EPOCH FROM w_profils.date_fin)::bigint, extract(EPOCH FROM w_profils.datedebutcontrat)::bigint]))[2], 0))::date AS date_debut, -- date de début du dernier contrat.
|
|
to_timestamp(coalesce((max(array[extract(EPOCH FROM w_profils.date_fin)::bigint, extract(EPOCH FROM w_profils.datefincontrat)::bigint]))[2], 0))::date AS date_fin, -- date de fin du dernier contrat.
|
|
psa_dateentree::date AS date_entree_ets,
|
|
(CASE WHEN psa_datesortie::date = '1900-01-01' THEN '2099-12-31' ELSE psa_datesortie END)::date AS date_sortie_ets,
|
|
-- Champs dédiés au public.
|
|
psa_dateentree::date AS date_entree_fp,
|
|
psa_dateentree::date AS date_entree_fph,
|
|
0 AS no_adeli,
|
|
0 AS code_cotisation_id,
|
|
0 AS matricule_retraite
|
|
FROM prod_cegid.salaries
|
|
LEFT JOIN rh.t_codes_postaux ON t_codes_postaux.code = psa_codepostal
|
|
LEFT JOIN rh.t_situations_famille ON t_situations_famille.code_original = psa_situationfamil
|
|
LEFT JOIN rh.t_entreprises ON t_entreprises.code_original = psa_etablissement
|
|
LEFT JOIN rh.t_nationalites ON t_nationalites.code_original = psa_nationalite
|
|
LEFT JOIN w_profils ON w_profils.matricule = salaries.psa_salarie
|
|
GROUP BY 1,2,3,4,5,6,7,8,9,10,11,12,13,17,18,19,20,21,22,23
|
|
;
|
|
|
|
]]></sqlcmd>
|
|
</NODE>
|
|
<NODE name="SALARIE" type="common" />
|
|
<NODE label="Contrats">
|
|
<sqlcmd><![CDATA[
|
|
|
|
TRUNCATE rh.p_contrats
|
|
;
|
|
|
|
ALTER SEQUENCE rh.s_contrats RESTART WITH 1
|
|
;
|
|
|
|
INSERT INTO rh.p_contrats
|
|
(
|
|
salarie_id,
|
|
date_debut,
|
|
date_fin,
|
|
numero_contrat,
|
|
code_original,
|
|
etablissement_id,
|
|
profil_id
|
|
)
|
|
SELECT
|
|
coalesce(p_salaries.oid,0) AS salarie_id,
|
|
w_contrattravail.date_debut,
|
|
w_contrattravail.date_fin,
|
|
w_contrattravail.numero_contrat,
|
|
w_contrattravail.numero_contrat AS code_original,
|
|
coalesce(t_etablissements.oid,0) AS etablissement_id,
|
|
coalesce((max(ARRAY[EXTRACT(EPOCH FROM w_profils.date_fin)::bigint, w_profils.profil_id]))[2], 0) AS profil_id
|
|
FROM w_contrattravail
|
|
JOIN rh.p_salaries ON p_salaries.matricule = pci_salarie
|
|
JOIN rh.t_etablissements ON t_etablissements.code_original = pci_etablissement
|
|
LEFT JOIN w_profils ON 1=1
|
|
AND w_profils.matricule = pci_salarie
|
|
AND w_profils.numero_contrat = pci_salarie::text||lpad(pci_ordre,4,'0')
|
|
GROUP BY 1,2,3,4,5,6
|
|
;
|
|
|
|
-- #correction
|
|
-- Si les dates d'entrée/sortie d'établissement semblent incohérentes par rapports aux dates des contrats, les corriger.
|
|
UPDATE rh.p_salaries
|
|
SET date_entree_ets = date_debut_contrat
|
|
FROM (SELECT salarie_id, min(date_debut) AS date_debut_contrat from rh.p_contrats group by 1) AS s
|
|
WHERE 1=1
|
|
AND p_salaries.oid = s.salarie_id
|
|
AND date_entree_ets > date_debut_contrat
|
|
;
|
|
|
|
UPDATE rh.p_salaries
|
|
SET date_entree_ets = date_debut_contrat
|
|
FROM (SELECT salarie_id, min(date_debut) AS date_debut_contrat from rh.p_contrats group by 1) AS s
|
|
WHERE 1=1
|
|
AND p_salaries.oid = s.salarie_id
|
|
AND to_char(date_entree_ets, 'YYYY')::numeric >= 2009
|
|
AND date_entree_ets < date_debut_contrat
|
|
;
|
|
|
|
UPDATE rh.p_salaries
|
|
SET date_sortie_ets = date_fin_contrat
|
|
FROM (SELECT salarie_id, max(date_fin) AS date_fin_contrat from rh.p_contrats group by 1) AS s
|
|
WHERE 1=1
|
|
AND p_salaries.oid = s.salarie_id
|
|
AND date_fin_contrat > date_sortie_ets
|
|
;
|
|
|
|
-- Calcul ancienneté au début de contrat
|
|
UPDATE rh.p_contrats
|
|
SET
|
|
anciennete_anterieure_jours = subq.anciennete_anterieure_jours,
|
|
anciennete_anterieure_calculee_mois = subq.anciennete_anterieure_calculee_mois
|
|
FROM (
|
|
SELECT
|
|
t1.numero_contrat,
|
|
sum(t2.duree) AS anciennete_anterieure_jours,
|
|
sum(t2.duree) / 30 AS anciennete_anterieure_calculee_mois
|
|
FROM w_contrattravail AS t1
|
|
JOIN w_contrattravail AS t2 ON 1=1
|
|
AND t2.pci_salarie = t1.pci_salarie
|
|
AND t2.pci_ordre < t1.pci_ordre
|
|
group by 1
|
|
) AS subq
|
|
WHERE 1=1
|
|
AND p_contrats.numero_contrat = subq.numero_contrat
|
|
;
|
|
|
|
TRUNCATE rh.p_contrats_mois
|
|
;
|
|
|
|
ALTER SEQUENCE rh.s_contrats_mois RESTART WITH 1
|
|
;
|
|
|
|
INSERT INTO rh.p_contrats_mois(
|
|
salarie_id,
|
|
contrat_id,
|
|
mois_activite,
|
|
date_debut,
|
|
date_fin,
|
|
nombre_entrees,
|
|
nombre_departs,
|
|
nombre_debut_contrat,
|
|
nombre_fin_contrat,
|
|
est_hors_periode,
|
|
present_debut_mois,
|
|
present_fin_mois,
|
|
equivalent_temps_plein,
|
|
age_id,
|
|
age_jours,
|
|
anciennete_jours,
|
|
anciennete_mois,
|
|
anciennete_annee_id
|
|
)
|
|
SELECT
|
|
p_salaries.oid AS salarie_id,
|
|
p_contrats.oid AS contrat_id,
|
|
p_calendrier_mois.mois AS mois,
|
|
GREATEST(p_calendrier_mois.date_debut, w_salarie_mois.date_debut) AS date_debut,
|
|
LEAST(p_calendrier_mois.date_fin, w_salarie_mois.date_fin) AS date_fin,
|
|
CASE WHEN p_salaries.date_entree_ets BETWEEN p_calendrier_mois.date_debut AND p_calendrier_mois.date_fin THEN 1 ELSE 0 END AS nombre_entrees,
|
|
CASE WHEN p_salaries.date_sortie_ets BETWEEN p_calendrier_mois.date_debut AND p_calendrier_mois.date_fin THEN 1 ELSE 0 END AS nombre_departs,
|
|
CASE WHEN p_contrats.date_debut BETWEEN p_calendrier_mois.date_debut AND p_calendrier_mois.date_fin THEN 1 ELSE 0 END AS nombre_debut_contrat,
|
|
CASE WHEN p_contrats.date_fin BETWEEN p_calendrier_mois.date_debut AND p_calendrier_mois.date_fin THEN 1 ELSE 0 END AS nombre_fin_contrat,
|
|
w_salarie_mois.est_hors_periode,
|
|
CASE WHEN p_calendrier_mois.date_debut BETWEEN p_contrats.date_debut AND p_contrats.date_fin THEN 1 ELSE 0 END AS present_debut_mois,
|
|
CASE WHEN p_calendrier_mois.date_fin BETWEEN p_contrats.date_debut AND p_contrats.date_fin THEN 1 ELSE 0 END AS present_fin_mois,
|
|
0, -- L'ETP théorique est calculé plus loin à l'issue de la "Ventilation des profils".
|
|
base.cti_age(LEAST(p_calendrier_mois.date_fin, w_salarie_mois.date_fin), COALESCE(p_salaries.date_naissance, '1962-04-18'::date), 'ny') AS age_id,
|
|
LEAST(p_calendrier_mois.date_fin, w_salarie_mois.date_fin)::date - COALESCE(p_salaries.date_naissance, '1962-04-18'::date) AS age_jours,
|
|
p_contrats.anciennete_anterieure_jours
|
|
+ (LEAST(p_calendrier_mois.date_fin, w_salarie_mois.date_fin) - p_contrats.date_debut)
|
|
+ 1
|
|
AS anciennete_jours,
|
|
base.cti_months_between(p_contrats.date_debut, p_calendrier_mois.date_fin)
|
|
+ p_contrats.anciennete_anterieure_calculee_mois
|
|
AS anciennete_mois,
|
|
floor(
|
|
(
|
|
base.cti_months_between(p_contrats.date_debut, p_calendrier_mois.date_fin)
|
|
+ p_contrats.anciennete_anterieure_calculee_mois
|
|
) / 12
|
|
) AS anciennete_annee_id
|
|
FROM w_salarie_mois
|
|
JOIN base.p_calendrier_mois ON base.cti_overlaps(w_salarie_mois.date_debut, w_salarie_mois.date_fin, p_calendrier_mois.date_debut, p_calendrier_mois.date_fin)
|
|
JOIN rh.p_contrats ON p_contrats.numero_contrat = w_salarie_mois.numero_contrat
|
|
JOIN rh.p_salaries ON p_salaries.matricule = w_salarie_mois.matricule
|
|
WHERE 1=1
|
|
AND p_calendrier_mois.mois < to_char(now() + '1 month'::interval, 'YYYYMM')
|
|
GROUP BY 1,2,3,4,5,6,7,8,9,10,11,12,13,14,15,16,17
|
|
;
|
|
|
|
]]></sqlcmd>
|
|
</NODE>
|
|
<NODE label="Historique de la paie 0">
|
|
<sqlcmd><![CDATA[
|
|
|
|
DROP TABLE IF EXISTS w_comptes_s
|
|
;
|
|
|
|
CREATE TEMP TABLE w_comptes_s AS
|
|
select
|
|
''::text as rub,
|
|
''::text as cpt
|
|
limit 0
|
|
;
|
|
|
|
DROP TABLE IF EXISTS w_comptes_p
|
|
;
|
|
|
|
CREATE TEMP TABLE w_comptes_p AS
|
|
select
|
|
''::text as rub,
|
|
''::text as cpt
|
|
limit 0
|
|
;
|
|
|
|
DROP TABLE IF EXISTS w_histobulletin
|
|
;
|
|
|
|
CREATE TEMP TABLE w_histobulletin AS
|
|
select *
|
|
from prod_cegid.histobulletin
|
|
;
|
|
|
|
UPDATE w_histobulletin
|
|
SET PHB_SENSBUL = trim(PHB_SENSBUL)
|
|
WHERE PHB_SENSBUL <> trim(PHB_SENSBUL)
|
|
;
|
|
|
|
ANALYSE w_histobulletin
|
|
;
|
|
|
|
]]></sqlcmd>
|
|
</NODE>
|
|
<NODE label="Comptes">
|
|
<condition><![CDATA[
|
|
|
|
-- Si la table
|
|
select count(*) = 1
|
|
from information_schema.tables
|
|
where 1=1
|
|
and table_schema = 'prod_cegid'
|
|
and table_name = 'pgremavecventil'
|
|
;
|
|
|
|
]]></condition>
|
|
<sqlcmd><![CDATA[
|
|
|
|
insert into w_comptes_s
|
|
select
|
|
pvs_rubrique as rub,
|
|
(max(array[case when pvs_predefini = 'STD' then '1' else '0' end, pvs_racine1]))[2] as cpt
|
|
from prod_cegid.pgremavecventil
|
|
group by 1
|
|
;
|
|
|
|
insert into w_comptes_p
|
|
select
|
|
pvt_rubrique as rub,
|
|
(max(array[case when pvt_predefini = 'STD' then '1' else '0' end, pvt_racine2]))[2] as cpt
|
|
from prod_cegid.pgcotavecventil
|
|
group by 1
|
|
;
|
|
|
|
]]></sqlcmd>
|
|
</NODE>
|
|
<NODE label="Historique de la paie 1">
|
|
<condition><![CDATA[
|
|
|
|
-- Si la table paieencours n'a pas de colonne phb_omtsalarial, on la rajoute à la volée.
|
|
select count(*) = 0
|
|
from information_schema.columns
|
|
where 1=1
|
|
and table_schema = 'prod_cegid'
|
|
and table_name = 'histobulletin'
|
|
and column_name = 'phb_omtsalarial'
|
|
;
|
|
|
|
]]></condition>
|
|
<sqlcmd><![CDATA[
|
|
|
|
-- Création de la colonne.
|
|
ALTER TABLE w_histobulletin ADD COLUMN phb_omtsalarial numeric
|
|
;
|
|
|
|
-- Alimentation de la colonne.
|
|
UPDATE w_histobulletin SET
|
|
phb_omtsalarial = 0
|
|
;
|
|
|
|
]]></sqlcmd>
|
|
</NODE>
|
|
<NODE label="Historique de la paie 2 (mode paramétré)">
|
|
<condition><![CDATA[
|
|
|
|
-- Historique de paie paramétré.
|
|
select valeur = 1
|
|
from rh.t_divers
|
|
where code = 'OPT_STD_HP'
|
|
;
|
|
|
|
]]></condition>
|
|
<sqlcmd><![CDATA[
|
|
|
|
-- 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
|
|
phb_rubrique||'-'||phb_ordreetat AS codrubrique,
|
|
phb_ordreetat = 1 as brut,
|
|
false as hresp,
|
|
false as hresw,
|
|
phb_ordreetat = 7 as odns,
|
|
false as odnp,
|
|
phb_ordreetat = 3 as cosd,
|
|
phb_ordreetat = 3 as copa
|
|
FROM w_histobulletin
|
|
WHERE 1=1
|
|
AND (1!=1
|
|
OR phb_mtrem <> 0
|
|
OR phb_mtsalarial <> 0
|
|
OR phb_mtpatronal <> 0
|
|
)
|
|
GROUP BY 1,2,3,4,5,6,7,8
|
|
)
|
|
, rub_det_1 as (
|
|
select
|
|
codrubrique,
|
|
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,
|
|
bool_or(brut) or bool_or(cosd) or bool_or(odns) AS p_net_a_payer
|
|
from rub_det_0
|
|
group by 1
|
|
)
|
|
|
|
SELECT
|
|
codrubrique as code_original,
|
|
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,
|
|
1 as c_net_imposable,
|
|
p_net_a_payer as p_net_a_payer,
|
|
3 as s_net_a_payer,
|
|
1 as c_net_a_payer
|
|
FROM rub_det_1
|
|
;
|
|
|
|
-- Pré-paramétrage automatique des rubriques (au mieux).
|
|
-- Cette requête n'intervient pas sur les rubriques paramétrées à la main.
|
|
update rh.t_rubriques
|
|
set
|
|
p_cumul = x_ref_rubrique.p_cumul,
|
|
p_detail = x_ref_rubrique.p_detail,
|
|
p_nombre = x_ref_rubrique.p_nombre,
|
|
s_nombre = x_ref_rubrique.s_nombre,
|
|
c_nombre = x_ref_rubrique.c_nombre,
|
|
p_base = x_ref_rubrique.p_base,
|
|
s_base = x_ref_rubrique.s_base,
|
|
c_base = x_ref_rubrique.c_base,
|
|
p_heures_contrat = x_ref_rubrique.p_heures_contrat,
|
|
s_heures_contrat = x_ref_rubrique.s_heures_contrat,
|
|
c_heures_contrat = x_ref_rubrique.c_heures_contrat,
|
|
p_heures_payees = x_ref_rubrique.p_heures_payees,
|
|
s_heures_payees = x_ref_rubrique.s_heures_payees,
|
|
c_heures_payees = x_ref_rubrique.c_heures_payees,
|
|
p_heures_travaillees = x_ref_rubrique.p_heures_travaillees,
|
|
s_heures_travaillees = x_ref_rubrique.s_heures_travaillees,
|
|
c_heures_travaillees = x_ref_rubrique.c_heures_travaillees,
|
|
p_masse_salariale = x_ref_rubrique.p_masse_salariale,
|
|
s_masse_salariale = x_ref_rubrique.s_masse_salariale,
|
|
c_masse_salariale = x_ref_rubrique.c_masse_salariale,
|
|
p_brut = x_ref_rubrique.p_brut,
|
|
s_brut = x_ref_rubrique.s_brut,
|
|
c_brut = x_ref_rubrique.c_brut,
|
|
p_avantage_nature = x_ref_rubrique.p_avantage_nature,
|
|
s_avantage_nature = x_ref_rubrique.s_avantage_nature,
|
|
c_avantage_nature = x_ref_rubrique.c_avantage_nature,
|
|
p_frais_imposables = x_ref_rubrique.p_frais_imposables,
|
|
s_frais_imposables = x_ref_rubrique.s_frais_imposables,
|
|
c_frais_imposables = x_ref_rubrique.c_frais_imposables,
|
|
p_cotisation_salarie = x_ref_rubrique.p_cotisation_salarie,
|
|
s_cotisation_salarie = x_ref_rubrique.s_cotisation_salarie,
|
|
c_cotisation_salarie = x_ref_rubrique.c_cotisation_salarie,
|
|
p_cotisation_patronale = x_ref_rubrique.p_cotisation_patronale,
|
|
s_cotisation_patronale = x_ref_rubrique.s_cotisation_patronale,
|
|
c_cotisation_patronale = x_ref_rubrique.c_cotisation_patronale,
|
|
p_od_net_salarie = x_ref_rubrique.p_od_net_salarie,
|
|
s_od_net_salarie = x_ref_rubrique.s_od_net_salarie,
|
|
c_od_net_salarie = x_ref_rubrique.c_od_net_salarie,
|
|
p_od_net_patronale = x_ref_rubrique.p_od_net_patronale,
|
|
s_od_net_patronale = x_ref_rubrique.s_od_net_patronale,
|
|
c_od_net_patronale = x_ref_rubrique.c_od_net_patronale,
|
|
p_net_imposable = x_ref_rubrique.p_net_imposable,
|
|
s_net_imposable = x_ref_rubrique.s_net_imposable,
|
|
c_net_imposable = x_ref_rubrique.c_net_imposable,
|
|
p_net_a_payer = x_ref_rubrique.p_net_a_payer,
|
|
s_net_a_payer = x_ref_rubrique.s_net_a_payer,
|
|
c_net_a_payer = x_ref_rubrique.c_net_a_payer
|
|
from temp.x_ref_rubrique
|
|
where 1=1
|
|
AND t_rubriques.code_original = x_ref_rubrique.code_original
|
|
AND NOT t_rubriques.user_modified
|
|
;
|
|
|
|
DROP TABLE IF EXISTS temp.x_hst_paie
|
|
;
|
|
|
|
CREATE TABLE temp.x_hst_paie AS
|
|
(
|
|
SELECT
|
|
'histobulletin'::text || histobulletin.CTID::text AS source,
|
|
w_histosalarie.date_fin AS histosalarie_date_fin,
|
|
w_histosalarie.CTID::text AS histosalarie_ctid,
|
|
phb_etablissement::text||'-'||phb_salarie::text||'-'||phb_datefin::text as bul_id,
|
|
phb_etablissement AS ety_code_original,
|
|
phb_salarie AS sal_code_original,
|
|
phb_datedebut::date AS date_debut,
|
|
phb_datefin::date AS date_fin,
|
|
to_char(phb_datefin,'YYYYMM')::numeric AS mois,
|
|
phb_rubrique||'-'||phb_ordreetat AS rub_code_original,
|
|
case when phb_mtpatronal != 0 then w_comptes_p.cpt else w_comptes_s.cpt end as cpt,
|
|
phb_organisme AS organisme,
|
|
coalesce(nullif((max(ARRAY[extract(epoch from w_histosalarie.date_debut), w_histosalarie.phs_ttauxpartiel]))[2], 0) / 100.0, 1.0) as etp_contrat,
|
|
sum(phb_baserem * (CASE WHEN phb_sensbul = 'P' THEN 1 ELSE -1 END)) AS base,
|
|
sum(CASE WHEN phb_ordreetat in (1, 2, 6, 7) THEN phb_tauxrem ELSE phb_tauxsalarial END) AS txsal,
|
|
sum((phb_mtrem + phb_mtsalarial * -1.0) * (CASE WHEN phb_sensbul = 'P' THEN 1 ELSE -1 END)) AS mntsal,
|
|
sum(phb_tauxpatronal) AS txpat,
|
|
sum(phb_mtpatronal * (CASE WHEN phb_sensbul = 'P' THEN 1 ELSE -1 END)) AS mntpat
|
|
FROM w_histobulletin as histobulletin
|
|
left join w_histosalarie on 1=1
|
|
and w_histosalarie.phs_salarie = histobulletin.phb_salarie
|
|
and base.cti_overlaps(w_histosalarie.date_debut, w_histosalarie.date_fin, histobulletin.phb_datedebut::date, histobulletin.phb_datefin::date)
|
|
left join w_comptes_s on w_comptes_s.rub = histobulletin.phb_rubrique
|
|
left join w_comptes_p on w_comptes_p.rub = histobulletin.phb_rubrique
|
|
WHERE 1=1
|
|
AND (1!=1
|
|
OR phb_mtrem <> 0
|
|
OR phb_mtsalarial <> 0
|
|
OR phb_mtpatronal <> 0
|
|
)
|
|
AND date_part('year', phb_datefin) >= to_char(rhp('rhprovider_start')::date, 'YYYY')
|
|
GROUP BY 1,2,3,4,5,6,7,8,9,10,11,12, histobulletin.ctid
|
|
)
|
|
UNION ALL
|
|
(
|
|
SELECT
|
|
'histocumsal'::text || histocumsal.CTID::text AS source,
|
|
w_histosalarie.date_fin AS histosalarie_date_fin,
|
|
w_histosalarie.CTID::text AS histosalarie_ctid,
|
|
phc_etablissement::text||'-'||phc_salarie::text||'-'||phc_datefin::text as bul_id,
|
|
phc_etablissement AS ety_code_original,
|
|
phc_salarie AS sal_code_original,
|
|
phc_datedebut::date AS date_debut,
|
|
phc_datefin::date AS date_fin,
|
|
to_char(phc_datefin,'YYYYMM')::numeric AS mois,
|
|
'C'||lpad(phc_cumulpaie,3,'0') AS rub_code_original,
|
|
'' as cpt,
|
|
'' AS organisme,
|
|
coalesce(nullif((max(ARRAY[extract(epoch from w_histosalarie.date_debut), w_histosalarie.phs_ttauxpartiel]))[2], 0) / 100.0, 1.0) as etp_contrat,
|
|
CASE WHEN phc_cumulpaie in ('20', '21', '22') THEN phc_montant ELSE 0 END AS base,
|
|
0 AS txsal,
|
|
CASE WHEN phc_cumulpaie in ('01', '02', '08', '09', '10') THEN phc_montant ELSE 0 END as mntsal,
|
|
0 AS txpat,
|
|
CASE WHEN phc_cumulpaie = '07' THEN phc_montant ELSE 0 END as mntpat
|
|
FROM prod_cegid.histocumsal
|
|
left join w_histosalarie on 1=1
|
|
and w_histosalarie.phs_salarie = histocumsal.phc_salarie
|
|
and base.cti_overlaps(w_histosalarie.date_debut, w_histosalarie.date_fin, histocumsal.phc_datedebut::date, histocumsal.phc_datefin::date)
|
|
WHERE 1=1
|
|
AND phc_cumulpaie IN ('01', '02', '07', '08', '09', '10', '20', '21', '22')
|
|
AND date_part('year', phc_datefin) >= to_char(rhp('rhprovider_start')::date, 'YYYY')
|
|
GROUP BY 1,2,3,4,5,6,7,8,9,10,11,12, phc_montant, phc_cumulpaie, histocumsal.ctid
|
|
)
|
|
;
|
|
|
|
ANALYSE temp.x_hst_paie
|
|
;
|
|
|
|
-- Suppression des doublons dus à un écart entre dates contrats et dates paie
|
|
DELETE FROM temp.x_hst_paie
|
|
USING
|
|
(
|
|
SELECT source, count(*), (MAX(ARRAY[histosalarie_date_fin::text, histosalarie_ctid]))[2] AS keep_ctid
|
|
FROM temp.x_hst_paie
|
|
GROUP BY 1
|
|
HAVING count(*) > 1
|
|
) subview
|
|
WHERE x_hst_paie.source = subview.source AND
|
|
x_hst_paie.histosalarie_ctid <> keep_ctid
|
|
;
|
|
|
|
-- #specifique - Màj des jours des fofaits jours (rubrique 0007) en heures à partir de la table 'prod_cegid.histosalarie'.
|
|
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'
|
|
)
|
|
, heures as (
|
|
select
|
|
phs_salarie as matricule,
|
|
to_char(date_debut, 'YYYYMM') as mois_debut,
|
|
to_char(date_fin, 'YYYYMM') as mois_fin,
|
|
max(nb_heures) as nb_heures
|
|
from w_histosalarie
|
|
group by 1,2,3)
|
|
, forfaits as (
|
|
select
|
|
x_hst_paie.sal_code_original,
|
|
x_hst_paie.mois
|
|
from temp.x_hst_paie
|
|
WHERE 1=1
|
|
and rub_code_original in (select code_original from liste_rub_fj)
|
|
and @base = 0
|
|
)
|
|
UPDATE temp.x_hst_paie SET
|
|
base = nb_heures * (x_hst_paie.date_fin - x_hst_paie.date_debut + 1.0) / (base.cti_last_day(x_hst_paie.date_debut) - base.cti_first_day(x_hst_paie.date_debut) + 1.0)
|
|
FROM heures, forfaits
|
|
WHERE 1=1
|
|
and x_hst_paie.sal_code_original = heures.matricule
|
|
and x_hst_paie.sal_code_original = forfaits.sal_code_original
|
|
and x_hst_paie.mois between heures.mois_debut and heures.mois_fin
|
|
and x_hst_paie.mois = forfaits.mois
|
|
and rub_code_original = 'C021'
|
|
;
|
|
|
|
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'
|
|
)
|
|
, heures as (
|
|
select
|
|
phs_salarie as matricule,
|
|
to_char(date_debut, 'YYYYMM') as mois_debut,
|
|
to_char(date_fin, 'YYYYMM') as mois_fin,
|
|
max(nb_heures) as nb_heures
|
|
from w_histosalarie
|
|
group by 1,2,3)
|
|
UPDATE temp.x_hst_paie SET
|
|
base = nb_heures * (x_hst_paie.date_fin - x_hst_paie.date_debut + 1.0) / (base.cti_last_day(x_hst_paie.date_debut) - base.cti_first_day(x_hst_paie.date_debut) + 1.0)
|
|
FROM heures
|
|
WHERE 1=1
|
|
and x_hst_paie.sal_code_original = heures.matricule
|
|
and x_hst_paie.mois between heures.mois_debut and heures.mois_fin
|
|
and x_hst_paie.rub_code_original in (select code_original from liste_rub_fj)
|
|
and @base = 0
|
|
;
|
|
|
|
DROP TABLE IF EXISTS w_hp
|
|
;
|
|
|
|
CREATE TEMP TABLE w_hp AS
|
|
SELECT
|
|
x_hst_paie.bul_id,
|
|
t_etablissements.oid as etablissement_id,
|
|
p_salaries.oid as salarie_id,
|
|
x_hst_paie.sal_code_original,
|
|
x_hst_paie.sal_code_original AS matricule,
|
|
x_hst_paie.date_debut,
|
|
x_hst_paie.date_fin,
|
|
x_hst_paie.mois as mois_activite,
|
|
x_hst_paie.date_fin as date_paie,
|
|
x_hst_paie.mois as mois_paie,
|
|
t_rubriques.oid AS rubrique_id,
|
|
0::bigint as organisme_cotisation_id,
|
|
0::bigint as compte_id,
|
|
t_rubriques.c_base
|
|
* case when @t_rubriques.c_base != 1 then coalesce(case when proratiser_conversion then x_hst_paie.etp_contrat else 1.0 end, 1.0) else 1.0 end
|
|
* CASE WHEN p_base THEN (CASE s_base
|
|
WHEN 0 THEN base
|
|
WHEN 1 THEN base
|
|
WHEN 3 THEN mntsal
|
|
WHEN 5 THEN mntpat
|
|
END) else 0 end AS base,
|
|
t_rubriques.c_nombre
|
|
* case when @t_rubriques.c_nombre != 1 then coalesce(case when proratiser_conversion then x_hst_paie.etp_contrat else 1.0 end, 1.0) else 1.0 end
|
|
* CASE WHEN p_nombre THEN (CASE s_nombre
|
|
WHEN 0 THEN base
|
|
WHEN 1 THEN base
|
|
WHEN 3 THEN mntsal
|
|
WHEN 5 THEN mntpat
|
|
END) else 0 end AS nombre,
|
|
t_rubriques.c_heures_contrat
|
|
* case when @t_rubriques.c_heures_contrat != 1 then coalesce(case when proratiser_conversion then x_hst_paie.etp_contrat else 1.0 end, 1.0) else 1.0 end
|
|
* CASE WHEN p_heures_contrat
|
|
then (CASE s_heures_contrat
|
|
WHEN 0 THEN base
|
|
WHEN 1 THEN base
|
|
WHEN 3 THEN mntsal
|
|
WHEN 5 THEN mntpat
|
|
END)
|
|
else 0 end AS heure_contrat,
|
|
t_rubriques.c_heures_payees
|
|
* case when @t_rubriques.c_heures_payees != 1 then coalesce(case when proratiser_conversion then x_hst_paie.etp_contrat else 1.0 end, 1.0) else 1.0 end
|
|
* CASE WHEN p_heures_payees
|
|
then (CASE s_heures_payees
|
|
WHEN 0 THEN base
|
|
WHEN 1 THEN base
|
|
WHEN 3 THEN mntsal
|
|
WHEN 5 THEN mntpat
|
|
END)
|
|
else 0 end AS heure_payee,
|
|
t_rubriques.c_heures_travaillees
|
|
* case when @t_rubriques.c_heures_travaillees != 1 then coalesce(case when proratiser_conversion then x_hst_paie.etp_contrat else 1.0 end, 1.0) else 1.0 end
|
|
* CASE WHEN p_heures_travaillees
|
|
then (CASE s_heures_travaillees
|
|
WHEN 0 THEN base
|
|
WHEN 1 THEN base
|
|
WHEN 3 THEN mntsal
|
|
WHEN 5 THEN mntpat
|
|
END)
|
|
else 0 end AS heure_travaillee,
|
|
t_rubriques.c_masse_salariale *
|
|
CASE WHEN p_masse_salariale
|
|
THEN (CASE s_masse_salariale
|
|
WHEN 0 THEN base
|
|
WHEN 1 THEN base
|
|
WHEN 3 THEN mntsal
|
|
WHEN 5 THEN mntpat
|
|
END)
|
|
else 0 end AS montant_masse_salariale,
|
|
t_rubriques.c_brut *
|
|
CASE WHEN p_brut
|
|
THEN (CASE s_brut
|
|
WHEN 0 THEN base
|
|
WHEN 1 THEN base
|
|
WHEN 3 THEN mntsal
|
|
WHEN 5 THEN mntpat
|
|
END)
|
|
else 0 end AS montant_brut,
|
|
t_rubriques.c_frais_imposables *
|
|
case when p_frais_imposables
|
|
then (CASE s_frais_imposables
|
|
WHEN 0 THEN base
|
|
WHEN 1 THEN base
|
|
WHEN 3 THEN mntsal
|
|
WHEN 5 THEN mntpat
|
|
END)
|
|
else 0 end AS montant_frais_imposables,
|
|
t_rubriques.coefficient_txs *
|
|
case when p_cotisation_salarie
|
|
then txsal
|
|
else 0 end AS taux_cotisation_salarie,
|
|
t_rubriques.c_cotisation_salarie *
|
|
case when p_cotisation_salarie
|
|
then (CASE s_cotisation_salarie
|
|
WHEN 0 THEN base
|
|
WHEN 1 THEN base
|
|
WHEN 3 THEN mntsal
|
|
WHEN 5 THEN mntpat
|
|
END)
|
|
else 0 end AS montant_cotisation_salarie,
|
|
t_rubriques.coefficient_txp *
|
|
case when p_cotisation_patronale
|
|
then txpat
|
|
else 0 end AS taux_cotisation_patronale,
|
|
t_rubriques.c_cotisation_patronale *
|
|
case when p_cotisation_patronale
|
|
then (CASE s_cotisation_patronale
|
|
WHEN 0 THEN base
|
|
WHEN 1 THEN base
|
|
WHEN 3 THEN mntsal
|
|
WHEN 5 THEN mntpat
|
|
END)
|
|
else 0 end AS montant_cotisation_patronale,
|
|
t_rubriques.c_od_net_salarie *
|
|
CASE WHEN p_od_net_salarie
|
|
THEN (CASE s_od_net_salarie
|
|
WHEN 0 THEN base
|
|
WHEN 1 THEN base
|
|
WHEN 3 THEN mntsal
|
|
WHEN 5 THEN mntpat
|
|
END)
|
|
ELSE 0 END AS montant_od_net_salarie,
|
|
t_rubriques.c_od_net_patronale *
|
|
CASE WHEN p_od_net_patronale
|
|
THEN (CASE s_od_net_patronale
|
|
WHEN 0 THEN base
|
|
WHEN 1 THEN base
|
|
WHEN 3 THEN mntsal
|
|
WHEN 5 THEN mntpat
|
|
END)
|
|
ELSE 0 END AS montant_od_net_patronale,
|
|
t_rubriques.c_avantage_nature *
|
|
CASE WHEN p_avantage_nature
|
|
THEN (CASE s_avantage_nature
|
|
WHEN 0 THEN base
|
|
WHEN 1 THEN base
|
|
WHEN 3 THEN mntsal
|
|
WHEN 5 THEN mntpat
|
|
END)
|
|
ELSE 0 END AS montant_avantage_nature,
|
|
t_rubriques.c_net_imposable *
|
|
CASE WHEN p_net_imposable
|
|
THEN (CASE s_net_imposable
|
|
WHEN 0 THEN base
|
|
WHEN 1 THEN base
|
|
WHEN 3 THEN mntsal
|
|
WHEN 5 THEN mntpat
|
|
WHEN 6 THEN mntsal + mntpat
|
|
WHEN 7 THEN mntsal - mntpat
|
|
WHEN 8 THEN -mntsal + mntpat
|
|
END)
|
|
ELSE 0 END AS montant_net_imposable_salarie,
|
|
t_rubriques.c_net_a_payer *
|
|
CASE WHEN p_net_a_payer
|
|
THEN (CASE s_net_a_payer
|
|
WHEN 0 THEN base
|
|
WHEN 1 THEN base
|
|
WHEN 3 THEN mntsal
|
|
WHEN 5 THEN mntpat
|
|
END)
|
|
ELSE 0 END AS montant_net_a_payer_salarie,
|
|
t_rubriques.c_nombre_provisions *
|
|
CASE WHEN p_nombre_provisions
|
|
THEN (CASE s_nombre_provisions
|
|
WHEN 0 THEN base
|
|
WHEN 1 THEN base
|
|
WHEN 3 THEN mntsal
|
|
WHEN 5 THEN mntpat
|
|
END)
|
|
ELSE 0 END AS nombre_provisions,
|
|
t_rubriques.c_montant_provisions *
|
|
CASE WHEN p_montant_provisions
|
|
THEN (CASE s_montant_provisions
|
|
WHEN 0 THEN base
|
|
WHEN 1 THEN base
|
|
WHEN 3 THEN mntsal
|
|
WHEN 5 THEN mntpat
|
|
END)
|
|
ELSE 0 END AS montant_provisions,
|
|
t_rubriques.c_masse_salariale_provisionnee *
|
|
CASE WHEN p_masse_salariale_provisionnee
|
|
THEN (CASE s_masse_salariale_provisionnee
|
|
WHEN 0 THEN base
|
|
WHEN 1 THEN base
|
|
WHEN 3 THEN mntsal
|
|
WHEN 5 THEN mntpat
|
|
END)
|
|
ELSE 0 END AS montant_masse_salariale_provisionnee,
|
|
t_rubriques.p_cumul,
|
|
t_rubriques.p_detail,
|
|
(max(ARRAY[extract(epoch from p_contrats_mois.date_debut), p_contrats_mois.oid]))[2] as contrat_mois_id,
|
|
(max(ARRAY[extract(epoch from p_contrats_mois.date_debut), p_contrats_mois.contrat_id]))[2] as contrat_id,
|
|
0::bigint as profil_id
|
|
FROM temp.x_hst_paie
|
|
JOIN rh.t_rubriques ON t_rubriques.code_original = x_hst_paie.rub_code_original
|
|
join rh.p_salaries on p_salaries.code_original = x_hst_paie.sal_code_original
|
|
join rh.t_etablissements on t_etablissements.code_original = x_hst_paie.ety_code_original
|
|
left JOIN rh.p_contrats_mois ON 1=1
|
|
and p_contrats_mois.salarie_id = p_salaries.oid
|
|
AND base.cti_overlaps(p_contrats_mois.date_debut, p_contrats_mois.date_fin, x_hst_paie.date_debut, x_hst_paie.date_fin)
|
|
where false
|
|
OR t_rubriques.p_detail
|
|
OR t_rubriques.p_cumul
|
|
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, x_hst_paie.ctid -- ce dernier regroupement nous assure de ne pas aggréger à tort des colonnes.
|
|
;
|
|
|
|
-- #correction Si un bulletin n'a pas de contrat rattaché.
|
|
UPDATE w_hp SET
|
|
contrat_id = subq.contrat_id,
|
|
contrat_mois_id = subq.contrat_mois_id
|
|
FROM (
|
|
select
|
|
w_hp.bul_id,
|
|
(max(ARRAY[EXTRACT(EPOCH FROM p_contrats_mois.date_fin), p_contrats_mois.contrat_id]))[2] as contrat_id,
|
|
(max(ARRAY[EXTRACT(EPOCH FROM p_contrats_mois.date_fin), p_contrats_mois.oid]))[2] as contrat_mois_id
|
|
from w_hp
|
|
JOIN rh.p_contrats_mois ON p_contrats_mois.salarie_id = w_hp.salarie_id
|
|
where w_hp.contrat_mois_id is null
|
|
group by 1) as subq
|
|
WHERE w_hp.bul_id = subq.bul_id
|
|
;
|
|
|
|
-- Génération paie
|
|
SELECT base.cti_stash_table_indexes('rh', 'p_historique_paie')
|
|
;
|
|
|
|
TRUNCATE rh.p_historique_paie
|
|
;
|
|
|
|
INSERT INTO rh.p_historique_paie(
|
|
code_original,
|
|
etablissement_id,
|
|
age_id,
|
|
contrat_id,
|
|
contrat_mois_id,
|
|
date_debut,
|
|
date_fin,
|
|
mois_activite,
|
|
date_paie,
|
|
mois_paie,
|
|
base,
|
|
nombre,
|
|
heure_contrat,
|
|
heure_payee,
|
|
heure_travaillee,
|
|
montant_masse_salariale,
|
|
montant_brut,
|
|
montant_avantage_nature,
|
|
montant_frais_imposables,
|
|
montant_cotisation_salarie,
|
|
montant_cotisation_patronale,
|
|
montant_od_net_salarie,
|
|
montant_od_net_patronale,
|
|
montant_net_imposable_salarie,
|
|
montant_net_a_payer_salarie,
|
|
taux_cotisation_salarie,
|
|
taux_cotisation_patronale,
|
|
organisme_cotisation_id,
|
|
profil_id,
|
|
rubrique_id,
|
|
compte_id,
|
|
salarie_id,
|
|
nombre_provisions,
|
|
montant_provisions,
|
|
montant_masse_salariale_provisionnee)
|
|
SELECT
|
|
w_hp.bul_id,
|
|
w_hp.etablissement_id,
|
|
date_part('year', age(w_hp.date_fin, p_salaries.date_naissance)) AS age_id,
|
|
w_hp.contrat_id,
|
|
w_hp.contrat_mois_id,
|
|
w_hp.date_debut,
|
|
w_hp.date_fin,
|
|
w_hp.mois_activite,
|
|
w_hp.date_paie,
|
|
w_hp.mois_paie,
|
|
w_hp.base,
|
|
w_hp.nombre,
|
|
w_hp.heure_contrat,
|
|
w_hp.heure_payee,
|
|
w_hp.heure_travaillee,
|
|
w_hp.montant_masse_salariale,
|
|
w_hp.montant_brut,
|
|
w_hp.montant_avantage_nature,
|
|
w_hp.montant_frais_imposables,
|
|
w_hp.montant_cotisation_salarie,
|
|
w_hp.montant_cotisation_patronale,
|
|
w_hp.montant_od_net_salarie,
|
|
w_hp.montant_od_net_patronale,
|
|
w_hp.montant_net_imposable_salarie,
|
|
w_hp.montant_net_a_payer_salarie,
|
|
w_hp.taux_cotisation_salarie,
|
|
w_hp.taux_cotisation_patronale,
|
|
w_hp.organisme_cotisation_id,
|
|
w_hp.profil_id,
|
|
w_hp.rubrique_id,
|
|
w_hp.compte_id,
|
|
w_hp.salarie_id,
|
|
w_hp.nombre_provisions,
|
|
w_hp.montant_provisions,
|
|
w_hp.montant_masse_salariale_provisionnee
|
|
FROM w_hp
|
|
JOIN rh.p_salaries ON p_salaries.matricule = w_hp.matricule
|
|
where p_detail
|
|
;
|
|
|
|
SELECT base.cti_stash_pop_table_indexes('rh', 'p_historique_paie')
|
|
;
|
|
|
|
-- Création d'une table récapitulative des écarts à calculer par indicateur de paie (1 seule ligne).
|
|
DROP TABLE IF EXISTS w_cumul
|
|
;
|
|
|
|
CREATE TEMP TABLE w_cumul AS
|
|
SELECT
|
|
bool_or(p_cumul and p_heures_contrat) as total_heures_contrat,
|
|
bool_or(p_cumul and p_heures_payees) as total_heures_payees,
|
|
bool_or(p_cumul and p_heures_travaillees) as total_heures_travaillees,
|
|
bool_or(p_cumul and p_masse_salariale) as total_masse_salariale,
|
|
bool_or(p_cumul and p_brut) as total_brut,
|
|
bool_or(p_cumul and p_avantage_nature) as total_avantage_nature,
|
|
bool_or(p_cumul and p_frais_imposables) as total_frais_imposables,
|
|
bool_or(p_cumul and p_cotisation_salarie) as total_cotisation_salarie,
|
|
bool_or(p_cumul and p_cotisation_patronale) as total_cotisation_patronale,
|
|
bool_or(p_cumul and p_od_net_salarie) as total_od_net_salarie,
|
|
bool_or(p_cumul and p_od_net_patronale) as total_od_net_patronale,
|
|
bool_or(p_cumul and p_net_imposable) as total_net_imposable,
|
|
bool_or(p_cumul and p_net_a_payer) as total_net_a_payer,
|
|
bool_or(p_cumul and p_nombre_provisions) as total_nombre_provisions,
|
|
bool_or(p_cumul and p_montant_provisions) as total_montant_provisions,
|
|
bool_or(p_cumul and p_masse_salariale_provisionnee) as total_masse_salariale_provisionnee
|
|
FROM rh.t_rubriques
|
|
;
|
|
|
|
-- Création d'une table temp qui regroupe tous les totaux à atteindre pour calculer l'écart
|
|
DROP TABLE IF EXISTS w_totaux
|
|
;
|
|
|
|
CREATE TEMP TABLE w_totaux AS
|
|
SELECT
|
|
w_hp.bul_id,
|
|
w_hp.etablissement_id,
|
|
w_hp.salarie_id,
|
|
w_hp.mois_paie,
|
|
sum(case when p_heures_contrat then heure_contrat else 0 end) as heure_contrat,
|
|
sum(case when p_heures_payees then heure_payee else 0 end) as heure_payee,
|
|
sum(case when p_heures_travaillees then heure_travaillee else 0 end) as heure_travaillee,
|
|
sum(case when p_masse_salariale then montant_masse_salariale else 0 end) as montant_masse_salariale,
|
|
sum(case when p_brut then montant_brut else 0 end) AS montant_brut,
|
|
sum(case when p_avantage_nature then montant_avantage_nature else 0 end) as montant_avantage_nature,
|
|
sum(case when p_frais_imposables then montant_frais_imposables else 0 end) as montant_frais_imposables,
|
|
sum(case when p_cotisation_salarie then montant_cotisation_salarie else 0 end) AS montant_cotisation_salarie,
|
|
sum(case when p_cotisation_patronale then montant_cotisation_patronale else 0 end) AS montant_cotisation_patronale,
|
|
sum(case when p_od_net_salarie then montant_od_net_salarie else 0 end) as montant_od_net_salarie,
|
|
sum(case when p_od_net_patronale then montant_od_net_patronale else 0 end) as montant_od_net_patronale,
|
|
sum(case when p_net_imposable then montant_net_imposable_salarie else 0 end) as montant_net_imposable_salarie,
|
|
sum(case when p_net_a_payer then montant_net_a_payer_salarie else 0 end) as montant_net_a_payer_salarie,
|
|
sum(case when p_nombre_provisions then nombre_provisions else 0 end) as nombre_provisions,
|
|
sum(case when p_montant_provisions then montant_provisions else 0 end) as montant_provisions,
|
|
sum(case when p_masse_salariale_provisionnee then montant_masse_salariale_provisionnee else 0 end) as montant_masse_salariale_provisionnee
|
|
FROM w_hp
|
|
JOIN rh.t_rubriques ON t_rubriques.oid = w_hp.rubrique_id
|
|
where w_hp.p_cumul
|
|
GROUP BY 1,2,3,4
|
|
;
|
|
|
|
-- Insérer pour chaque bulletin une ligne qui va faire le compte avec le total (rubrique 'C000' nommée 'Ecart cumulé')
|
|
INSERT INTO rh.p_historique_paie (
|
|
code_original,
|
|
etablissement_id,
|
|
age_id,
|
|
contrat_id,
|
|
contrat_mois_id,
|
|
date_debut,
|
|
date_fin,
|
|
date_paie,
|
|
mois_activite,
|
|
mois_paie,
|
|
base,
|
|
nombre,
|
|
heure_contrat,
|
|
heure_payee,
|
|
heure_travaillee,
|
|
montant_masse_salariale,
|
|
montant_brut,
|
|
montant_avantage_nature,
|
|
montant_frais_imposables,
|
|
montant_cotisation_salarie,
|
|
montant_cotisation_patronale,
|
|
montant_od_net_salarie,
|
|
montant_od_net_patronale,
|
|
montant_net_imposable_salarie,
|
|
montant_net_a_payer_salarie,
|
|
organisme_cotisation_id,
|
|
profil_id,
|
|
rubrique_id,
|
|
compte_id,
|
|
salarie_id,
|
|
taux_cotisation_patronale,
|
|
taux_cotisation_salarie,
|
|
nombre_provisions,
|
|
montant_provisions,
|
|
montant_masse_salariale_provisionnee)
|
|
WITH subq as (
|
|
SELECT
|
|
p_historique_paie.code_original as bul_id,
|
|
p_historique_paie.etablissement_id,
|
|
p_historique_paie.age_id,
|
|
p_historique_paie.contrat_id,
|
|
p_historique_paie.contrat_mois_id,
|
|
p_historique_paie.date_debut,
|
|
p_historique_paie.date_fin,
|
|
p_historique_paie.date_paie,
|
|
p_historique_paie.mois_activite,
|
|
p_historique_paie.mois_paie,
|
|
0 AS base,
|
|
0 AS nombre,
|
|
organisme_cotisation_id AS organisme_cotisation_id,
|
|
profil_id AS profil_id,
|
|
(SELECT oid FROM rh.t_rubriques WHERE code = 'C000') as rubrique_id,
|
|
compte_id,
|
|
salarie_id,
|
|
0 AS taux_cotisation_patronale,
|
|
0 AS taux_cotisation_salarie,
|
|
sum(heure_contrat) AS heure_contrat,
|
|
sum(heure_payee) AS heure_payee,
|
|
sum(heure_travaillee) AS heure_travaillee,
|
|
sum(montant_masse_salariale) AS montant_masse_salariale,
|
|
sum(montant_brut) AS montant_brut,
|
|
sum(montant_avantage_nature) AS montant_avantage_nature,
|
|
sum(montant_frais_imposables) AS montant_frais_imposables,
|
|
sum(montant_cotisation_salarie) AS montant_cotisation_salarie,
|
|
sum(montant_cotisation_patronale) AS montant_cotisation_patronale,
|
|
sum(montant_od_net_salarie) AS montant_od_net_salarie,
|
|
sum(montant_od_net_patronale) AS montant_od_net_patronale,
|
|
sum(montant_net_imposable_salarie) AS montant_net_imposable_salarie,
|
|
sum(montant_net_a_payer_salarie) AS montant_net_a_payer_salarie,
|
|
sum(nombre_provisions) AS nombre_provisions,
|
|
sum(montant_provisions) AS montant_provisions,
|
|
sum(montant_masse_salariale_provisionnee) AS montant_masse_salariale_provisionnee
|
|
FROM rh.p_historique_paie
|
|
GROUP BY 1,2,3,4,5,6,7,8,9,10,11,12,13,14,15,16,17,18
|
|
)
|
|
SELECT
|
|
subq.bul_id,
|
|
subq.etablissement_id,
|
|
subq.age_id,
|
|
subq.contrat_id,
|
|
subq.contrat_mois_id,
|
|
subq.date_debut,
|
|
subq.date_fin,
|
|
subq.date_paie,
|
|
subq.mois_activite,
|
|
subq.mois_paie,
|
|
subq.base,
|
|
subq.nombre,
|
|
case when total_heures_contrat then w_totaux.heure_contrat - subq.heure_contrat else 0 end as heure_contrat,
|
|
case when total_heures_payees then w_totaux.heure_payee - subq.heure_payee else 0 end as heure_payee,
|
|
case when total_heures_travaillees then w_totaux.heure_travaillee - subq.heure_travaillee else 0 end as heure_travaillee,
|
|
case when total_masse_salariale then w_totaux.montant_masse_salariale - subq.montant_masse_salariale else 0 end as montant_masse_salariale,
|
|
case when total_brut then w_totaux.montant_brut - subq.montant_brut else 0 end as montant_brut,
|
|
case when total_avantage_nature then w_totaux.montant_avantage_nature - subq.montant_avantage_nature else 0 end as montant_avantage_nature,
|
|
case when total_frais_imposables then w_totaux.montant_frais_imposables - subq.montant_frais_imposables else 0 end as montant_frais_imposables,
|
|
case when total_cotisation_salarie then w_totaux.montant_cotisation_salarie - subq.montant_cotisation_salarie else 0 end as montant_cotisation_salarie,
|
|
case when total_cotisation_patronale then w_totaux.montant_cotisation_patronale - subq.montant_cotisation_patronale else 0 end as montant_cotisation_patronale,
|
|
case when total_od_net_salarie then w_totaux.montant_od_net_salarie - subq.montant_od_net_salarie else 0 end as montant_od_net_salarie,
|
|
case when total_od_net_patronale then w_totaux.montant_od_net_patronale - subq.montant_od_net_patronale else 0 end as montant_od_net_patronale,
|
|
case when total_net_imposable then w_totaux.montant_net_imposable_salarie - subq.montant_net_imposable_salarie else 0 end as montant_net_imposable_salarie,
|
|
case when total_net_a_payer then w_totaux.montant_net_a_payer_salarie - subq.montant_net_a_payer_salarie else 0 end as montant_net_a_payer_salarie,
|
|
subq.organisme_cotisation_id AS organisme_cotisation_id,
|
|
subq.profil_id,
|
|
subq.rubrique_id,
|
|
subq.compte_id,
|
|
subq.salarie_id,
|
|
subq.taux_cotisation_patronale,
|
|
subq.taux_cotisation_salarie,
|
|
case when total_nombre_provisions then w_totaux.nombre_provisions - subq.nombre_provisions else 0 end as nombre_provisions,
|
|
case when total_montant_provisions then w_totaux.montant_provisions - subq.montant_provisions else 0 end as montant_provisions,
|
|
case when total_masse_salariale_provisionnee then w_totaux.montant_masse_salariale_provisionnee - subq.montant_masse_salariale_provisionnee else 0 end as montant_masse_salariale_provisionnee
|
|
FROM subq
|
|
JOIN w_totaux ON w_totaux.bul_id = subq.bul_id
|
|
JOIN w_cumul ON true
|
|
WHERE 1!=1
|
|
OR (total_heures_contrat AND w_totaux.heure_contrat - subq.heure_contrat != 0)
|
|
OR (total_heures_payees AND w_totaux.heure_payee - subq.heure_payee != 0)
|
|
OR (total_heures_travaillees AND w_totaux.heure_travaillee - subq.heure_travaillee != 0)
|
|
OR (total_masse_salariale AND w_totaux.montant_masse_salariale - subq.montant_masse_salariale != 0)
|
|
OR (total_brut AND w_totaux.montant_brut - subq.montant_brut != 0)
|
|
OR (total_avantage_nature AND w_totaux.montant_avantage_nature - subq.montant_avantage_nature != 0)
|
|
OR (total_frais_imposables AND w_totaux.montant_frais_imposables - subq.montant_frais_imposables != 0)
|
|
OR (total_cotisation_salarie AND w_totaux.montant_cotisation_salarie - subq.montant_cotisation_salarie != 0)
|
|
OR (total_cotisation_patronale AND w_totaux.montant_cotisation_patronale - subq.montant_cotisation_patronale != 0)
|
|
OR (total_od_net_salarie AND w_totaux.montant_od_net_salarie - subq.montant_od_net_salarie != 0)
|
|
OR (total_od_net_patronale AND w_totaux.montant_od_net_patronale - subq.montant_od_net_patronale != 0)
|
|
OR (total_net_imposable AND w_totaux.montant_net_imposable_salarie - subq.montant_net_imposable_salarie != 0)
|
|
OR (total_net_a_payer AND w_totaux.montant_net_a_payer_salarie - subq.montant_net_a_payer_salarie != 0)
|
|
OR (total_nombre_provisions AND w_totaux.nombre_provisions - subq.nombre_provisions != 0)
|
|
OR (total_montant_provisions AND w_totaux.montant_provisions - subq.montant_provisions != 0)
|
|
OR (total_masse_salariale_provisionnee AND w_totaux.montant_masse_salariale_provisionnee - subq.montant_masse_salariale_provisionnee != 0)
|
|
;
|
|
|
|
]]></sqlcmd>
|
|
</NODE>
|
|
<NODE label="Historique de la paie 2 (mode classique)">
|
|
<condition><![CDATA[
|
|
|
|
-- Historique de paie classique.
|
|
select valeur = 0
|
|
from rh.t_divers
|
|
where code = 'OPT_STD_HP'
|
|
;
|
|
|
|
]]></condition>
|
|
<sqlcmd><![CDATA[
|
|
|
|
DROP TABLE IF EXISTS w_hp
|
|
;
|
|
|
|
CREATE TEMP TABLE w_hp AS
|
|
(
|
|
SELECT
|
|
phb_etablissement AS eta,
|
|
phb_salarie AS matricule,
|
|
phb_datedebut::date AS date_debut,
|
|
phb_datefin::date AS date_fin,
|
|
to_char(phb_datefin,'YYYYMM')::numeric AS mois,
|
|
phb_rubrique AS rubrique,
|
|
case when phb_mtpatronal != 0 then w_comptes_p.cpt else w_comptes_s.cpt end as cpt,
|
|
phb_organisme AS organisme,
|
|
sum(phb_baserem) AS base,
|
|
sum((CASE WHEN phb_ordreetat = 1 THEN phb_mtrem ELSE 0 END) * (CASE WHEN phb_sensbul = 'P' THEN 1 ELSE -1 END)) AS brut,
|
|
sum(CASE WHEN phb_ordreetat in (1, 2, 6, 7) THEN phb_tauxrem ELSE phb_tauxsalarial END) AS tx_sal,
|
|
sum(phb_mtsalarial * -1.0 * (CASE WHEN phb_sensbul = 'P' THEN 1 ELSE -1 END)) AS mt_sal,
|
|
sum(phb_tauxpatronal) AS tx_pat,
|
|
sum(phb_mtpatronal * (CASE WHEN phb_sensbul = 'P' THEN 1 ELSE -1 END)) AS mt_pat,
|
|
sum((CASE WHEN phb_ordreetat in (1, 2) THEN phb_mtrem ELSE 0 END + (case when phb_omtsalarial != 4 then phb_mtsalarial else 0.0 end * -1.0)) * (CASE WHEN phb_sensbul = 'P' THEN 1 ELSE -1 END)) AS net_imposable,
|
|
sum((CASE WHEN phb_ordreetat in (1, 2, 6, 7) THEN phb_mtrem ELSE 0 END + (phb_mtsalarial * -1.0)) * (CASE WHEN phb_sensbul = 'P' THEN 1 ELSE -1 END)) AS net_a_payer,
|
|
sum((CASE WHEN phb_ordreetat in (2, 6, 7) THEN phb_mtrem ELSE 0 END) * (CASE WHEN phb_sensbul = 'P' THEN 1 ELSE -1 END)) AS od_net
|
|
FROM w_histobulletin as histobulletin
|
|
left join w_comptes_s on w_comptes_s.rub = histobulletin.phb_rubrique
|
|
left join w_comptes_p on w_comptes_p.rub = histobulletin.phb_rubrique
|
|
WHERE 1=1
|
|
-- @WHERE_1 Même WHERE que pour le calcul du chiffrier
|
|
AND phb_imprimable = 'X'
|
|
AND (1!=1
|
|
OR phb_mtrem <> 0
|
|
OR phb_mtsalarial <> 0
|
|
OR phb_mtpatronal <> 0
|
|
)
|
|
AND phb_datefin::date - phb_datedebut::date < 31 -- pas les bulletins de paie sur plus d'un mois (lève le matricule 151)
|
|
-- date_part('month', phb_datefin) != date_part('month', phb_datedebut) -- (lève les matricules 151 et 1217)
|
|
--
|
|
AND date_part('year', phb_datefin) >= 2009
|
|
GROUP BY 1,2,3,4,5,6,7,8
|
|
)
|
|
UNION ALL
|
|
(
|
|
SELECT
|
|
phc_etablissement AS eta,
|
|
phc_salarie AS matricule,
|
|
phc_datedebut::date AS date_debut,
|
|
phc_datefin::date AS date_fin,
|
|
to_char(phc_datefin,'YYYYMM')::numeric AS mois,
|
|
'C'||lpad(phc_cumulpaie,3,'0') AS rubrique,
|
|
'' as cpt,
|
|
'' AS organisme,
|
|
CASE WHEN phc_cumulpaie in ('20', '21', '22') THEN phc_montant ELSE 0 END AS base,
|
|
0, --CASE WHEN phc_cumulpaie = '01' THEN phc_montant ELSE 0 END AS brut,
|
|
0 AS tx_sal,
|
|
0, --CASE WHEN phc_cumulpaie = '08' THEN phc_montant ELSE 0 END AS mt_sal,
|
|
0 AS tx_pat,
|
|
0,--CASE WHEN phc_cumulpaie = '07' THEN phc_montant ELSE 0 END AS mt_pat,
|
|
0 as net_imposable, --CASE WHEN phc_cumulpaie = '09' THEN phc_montant ELSE 0 END AS net_imposable,
|
|
0 AS net_a_payer,
|
|
0 AS od_net
|
|
FROM prod_cegid.histocumsal
|
|
WHERE 1=1
|
|
AND phc_cumulpaie IN ('20', '21', '22')
|
|
AND date_part('year', phc_datefin) >= 2009
|
|
)
|
|
UNION ALL
|
|
( -- Création de la rubrique C021 (heures payées) pour le parc à caen 243.
|
|
SELECT
|
|
phb_etablissement AS eta,
|
|
phb_salarie AS matricule,
|
|
phb_datedebut::date AS date_debut,
|
|
phb_datefin::date AS date_fin,
|
|
to_char(phb_datefin,'YYYYMM')::numeric AS mois,
|
|
'C021' AS rubrique,
|
|
'' as cpt,
|
|
'' AS organisme,
|
|
0 AS base, -- sera alimenté dans un second temps
|
|
0,
|
|
0 AS tx_sal,
|
|
0,
|
|
0 AS tx_pat,
|
|
0,
|
|
0 as net_imposable,
|
|
0 AS net_a_payer,
|
|
0 AS od_net
|
|
FROM w_histobulletin
|
|
LEFT JOIN prod_cegid.histocumsal on 1=1 -- Jointure avec la table des cumuls pour ne pas en re-créer 2 fois.
|
|
and histocumsal.phc_cumulpaie = '21'
|
|
and histocumsal.phc_salarie = w_histobulletin.phb_salarie
|
|
and histocumsal.phc_datefin = w_histobulletin.phb_datefin
|
|
WHERE 1=1
|
|
AND phb_rubrique = '0007'
|
|
and @phb_baserem = 0
|
|
and current_database() = 'icti_243'
|
|
and histocumsal.phc_cumulpaie is null
|
|
AND date_part('year', phb_datefin) >= 2009
|
|
)
|
|
;
|
|
|
|
CREATE INDEX i_w_hp_1
|
|
ON w_hp
|
|
USING btree (matricule)
|
|
;
|
|
|
|
CREATE INDEX i_w_hp_2
|
|
ON w_hp
|
|
USING btree (mois)
|
|
;
|
|
|
|
CREATE INDEX i_w_hp_3
|
|
ON w_hp
|
|
USING btree (rubrique)
|
|
;
|
|
|
|
-- Màj des jours d'absences (rubrique 3210) en heures d'absences à partir de la table 'absencesalarie'.
|
|
UPDATE w_hp
|
|
SET base = subq.heures
|
|
FROM (
|
|
SELECT
|
|
pcn_salarie::text AS matricule,
|
|
pcn_datedebut::date AS date_debut,
|
|
pcn_datefin::date AS date_fin,
|
|
sum(pcn_jours) AS jours,
|
|
sum(pcn_heures) AS heures
|
|
FROM prod_cegid.absencesalarie
|
|
WHERE 1=1
|
|
AND pcn_typeconge = 'PRI'
|
|
AND pcn_mvtduplique != 'X'
|
|
GROUP BY 1,2,3
|
|
) AS subq
|
|
WHERE 1=1
|
|
AND w_hp.matricule = subq.matricule
|
|
AND w_hp.date_debut = subq.date_debut
|
|
AND w_hp.date_fin = subq.date_fin
|
|
AND w_hp.base = subq.jours
|
|
AND w_hp.rubrique in ('3210', '6968')
|
|
;
|
|
|
|
-- #specifique 243 - Màj des jours des fofaits jours (rubrique 0007) en heures à partir de la table 'prod_cegid.histosalarie'.
|
|
with heures as (
|
|
select
|
|
phs_salarie as matricule,
|
|
to_char(date_debut, 'YYYYMM') as mois,
|
|
max(nb_heures) as nb_heures
|
|
from w_histosalarie
|
|
where current_database() = 'icti_243'
|
|
group by 1,2)
|
|
, forfaits as (
|
|
select
|
|
w_hp.matricule,
|
|
w_hp.mois
|
|
from w_hp
|
|
WHERE 1=1
|
|
and rubrique = '0007'
|
|
and @base = 0
|
|
and current_database() = 'icti_243'
|
|
)
|
|
UPDATE w_hp SET
|
|
base = nb_heures * (w_hp.date_fin - w_hp.date_debut + 1.0) / (base.cti_last_day(w_hp.date_debut) - base.cti_first_day(w_hp.date_debut) + 1.0)
|
|
FROM heures, forfaits
|
|
WHERE 1=1
|
|
and w_hp.matricule = heures.matricule
|
|
and w_hp.matricule = forfaits.matricule
|
|
and w_hp.mois = heures.mois
|
|
and w_hp.mois = forfaits.mois
|
|
and rubrique = 'C021'
|
|
and current_database() = 'icti_243'
|
|
;
|
|
|
|
with heures as (
|
|
select
|
|
phs_salarie as matricule,
|
|
to_char(date_debut, 'YYYYMM') as mois,
|
|
max(nb_heures) as nb_heures
|
|
from w_histosalarie
|
|
where current_database() = 'icti_243'
|
|
group by 1,2)
|
|
UPDATE w_hp SET
|
|
base = nb_heures * (w_hp.date_fin - w_hp.date_debut + 1.0) / (base.cti_last_day(w_hp.date_debut) - base.cti_first_day(w_hp.date_debut) + 1.0)
|
|
FROM heures
|
|
WHERE 1=1
|
|
and w_hp.matricule = heures.matricule
|
|
and w_hp.mois = heures.mois
|
|
and rubrique = '0007'
|
|
and @base = 0
|
|
and current_database() = 'icti_243'
|
|
;
|
|
|
|
-- Insertion dans la table de production CTI.
|
|
TRUNCATE rh.p_historique_paie
|
|
;
|
|
|
|
SELECT base.cti_stash_table_indexes('rh', 'p_historique_paie')
|
|
;
|
|
|
|
INSERT INTO rh.p_historique_paie
|
|
(
|
|
age_id,
|
|
base,
|
|
contrat_id,
|
|
contrat_mois_id,
|
|
date_debut,
|
|
date_fin,
|
|
date_paie,
|
|
mois_activite,
|
|
mois_paie,
|
|
montant_avantage_nature,
|
|
montant_brut,
|
|
montant_cotisation_patronale,
|
|
montant_cotisation_salarie,
|
|
montant_frais_imposables,
|
|
montant_net_a_payer_salarie,
|
|
montant_net_imposable_salarie,
|
|
montant_od_net_salarie,
|
|
organisme_cotisation_id,
|
|
profil_id, -- @deprecated
|
|
rubrique_id,
|
|
compte_id,
|
|
salarie_id,
|
|
taux_cotisation_patronale,
|
|
taux_cotisation_salarie
|
|
)
|
|
SELECT
|
|
date_part('year', age(w_hp.date_debut, date_naissance)) AS age_id,
|
|
w_hp.base AS base,
|
|
(max(ARRAY[EXTRACT(EPOCH FROM p_contrats_mois.date_fin),p_contrats_mois.contrat_id]))[2] AS contrat_id,
|
|
(max(ARRAY[EXTRACT(EPOCH FROM p_contrats_mois.date_fin),p_contrats_mois.oid]))[2] AS contrat_mois_id,
|
|
w_hp.date_debut AS date_debut,
|
|
w_hp.date_fin AS date_fin,
|
|
w_hp.date_fin AS date_paie,
|
|
w_hp.mois AS mois_activite,
|
|
w_hp.mois AS mois_paie,
|
|
0 AS montant_avantage_nature,
|
|
w_hp.brut AS montant_brut,
|
|
w_hp.mt_pat AS montant_cotisation_patronale,
|
|
w_hp.mt_sal AS montant_cotisation_salarie,
|
|
0 AS montant_frais_imposables,
|
|
w_hp.net_a_payer AS montant_net_a_payer_salarie,
|
|
w_hp.net_imposable AS montant_net_imposable_salarie,
|
|
w_hp.od_net AS montant_od_net_salarie,
|
|
coalesce(t_organismes_cotisation.oid, 0) AS organisme_cotisation_id,
|
|
0,-- (max(ARRAY[EXTRACT(EPOCH FROM p_contrats_mois.date_fin),p_contrats_mois.profil_id]))[2] AS profil_id,
|
|
t_rubriques.oid AS rubrique_id,
|
|
COALESCE(t_compte.oid,0) as compte_id,
|
|
p_salaries.oid AS salarie_id,
|
|
w_hp.tx_pat AS taux_cotisation_patronale,
|
|
w_hp.tx_sal AS taux_cotisation_salarie
|
|
FROM w_hp
|
|
JOIN rh.t_rubriques ON t_rubriques.code_original = w_hp.rubrique
|
|
JOIN rh.p_salaries ON p_salaries.matricule = w_hp.matricule
|
|
LEFT JOIN rh.t_compte on t_compte.code_original = w_hp.cpt
|
|
LEFT JOIN rh.t_organismes_cotisation ON t_organismes_cotisation.code_original = w_hp.organisme
|
|
LEFT JOIN rh.p_contrats_mois ON 1=1
|
|
AND p_contrats_mois.salarie_id = p_salaries.oid
|
|
--AND p_contrats_mois.mois_activite = w_hp.mois
|
|
AND base.cti_overlaps(p_contrats_mois.date_debut, p_contrats_mois.date_fin, w_hp.date_debut, w_hp.date_fin)
|
|
GROUP BY 1,2,5,6,7,8,9,10,11,12,13,14,15,16,17,18,20,21,22,23,24
|
|
;
|
|
|
|
SELECT base.cti_stash_pop_table_indexes('rh', 'p_historique_paie')
|
|
;
|
|
|
|
-- #correction Si un bulletin n'a pas de contrat rattaché.
|
|
UPDATE rh.p_historique_paie SET
|
|
contrat_id = subq.contrat_id,
|
|
contrat_mois_id = subq.contrat_mois_id
|
|
FROM (
|
|
select
|
|
p_historique_paie.salarie_id,
|
|
p_historique_paie.date_paie,
|
|
(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 rh.p_historique_paie
|
|
JOIN rh.p_contrats_mois ON p_contrats_mois.salarie_id = p_historique_paie.salarie_id
|
|
where p_historique_paie.contrat_mois_id is null
|
|
group by 1,2) as subq
|
|
WHERE true
|
|
AND p_historique_paie.salarie_id = subq.salarie_id
|
|
AND p_historique_paie.date_paie = subq.date_paie
|
|
;
|
|
|
|
-- Création d'une table temp qui regroupe tous les totaux à atteindre pour calculer l'écart
|
|
DROP TABLE IF EXISTS w_totaux
|
|
;
|
|
|
|
CREATE TEMP TABLE w_totaux AS
|
|
SELECT
|
|
ppu_salarie AS matricule,
|
|
ppu_datedebut AS date_debut,
|
|
ppu_datefin AS date_fin,
|
|
to_char(ppu_datefin,'YYYYMM')::numeric AS mois,
|
|
sum(ppu_cbrut)::numeric AS brut,
|
|
sum(ppu_cnetimposab)::numeric AS net_imposable,
|
|
sum(ppu_cnetapayer)::numeric AS net_a_payer,
|
|
sum(ppu_ccoutsalarie)::numeric * -1.0 AS mt_sal,
|
|
sum(ppu_ccoutpatron)::numeric AS mt_pat
|
|
FROM prod_cegid.paieencours
|
|
WHERE 1=1
|
|
AND date_part('year', ppu_datedebut) >= 2009
|
|
GROUP BY 1,2,3,4
|
|
;
|
|
|
|
-- Inserer pour chaque bulletin une ligne qui va faire le compte avec le total (rubrique 'C000' nommée 'Ecart cumulé')
|
|
INSERT INTO rh.p_historique_paie
|
|
(
|
|
age_id,
|
|
contrat_id,
|
|
contrat_mois_id,
|
|
date_debut,
|
|
date_fin,
|
|
date_paie,
|
|
mois_activite,
|
|
mois_paie,
|
|
base,
|
|
montant_avantage_nature,
|
|
montant_brut,
|
|
montant_cotisation_patronale,
|
|
montant_cotisation_salarie,
|
|
montant_frais_imposables,
|
|
montant_net_a_payer_salarie,
|
|
montant_net_imposable_salarie,
|
|
montant_od_net_salarie,
|
|
organisme_cotisation_id,
|
|
profil_id, -- @deprecated
|
|
rubrique_id,
|
|
compte_id,
|
|
salarie_id,
|
|
taux_cotisation_patronale,
|
|
taux_cotisation_salarie
|
|
)
|
|
SELECT
|
|
age_id,
|
|
contrat_id,
|
|
contrat_mois_id,
|
|
subq.date_debut,
|
|
subq.date_fin,
|
|
subq.date_paie,
|
|
subq.mois_activite,
|
|
subq.mois_paie,
|
|
0 AS base,
|
|
0 AS montant_avantage_nature,
|
|
sum(brut - subq.montant_brut) AS montant_brut,
|
|
sum(mt_pat - subq.montant_cotisation_patronale) AS montant_cotisation_patronale,
|
|
sum(mt_sal - subq.montant_cotisation_salarie) AS montant_cotisation_salarie,
|
|
0 AS montant_frais_imposables,
|
|
sum(net_a_payer - subq.montant_net_a_payer_salarie) AS montant_net_a_payer_salarie,
|
|
sum(net_imposable - subq.montant_net_imposable_salarie) AS montant_net_imposable_salarie,
|
|
0 AS montant_od_net_salarie,
|
|
subq.organisme_cotisation_id AS organisme_cotisation_id,
|
|
subq.profil_id AS profil_id,
|
|
(SELECT oid FROM rh.t_rubriques WHERE code = 'C000') AS rubrique_id,
|
|
0 as compte_id,
|
|
subq.salarie_id AS salarie_id,
|
|
0 AS taux_cotisation_patronale,
|
|
0 AS taux_cotisation_salarie
|
|
FROM
|
|
(
|
|
SELECT
|
|
p_historique_paie.age_id,
|
|
p_historique_paie.contrat_id,
|
|
p_historique_paie.contrat_mois_id,
|
|
p_historique_paie.date_debut,
|
|
p_historique_paie.date_fin,
|
|
p_historique_paie.date_paie,
|
|
p_historique_paie.mois_activite,
|
|
p_historique_paie.mois_paie,
|
|
0 AS base,
|
|
sum(montant_avantage_nature) AS montant_avantage_nature,
|
|
sum(montant_brut) AS montant_brut,
|
|
sum(montant_cotisation_patronale) AS montant_cotisation_patronale,
|
|
sum(montant_cotisation_salarie) AS montant_cotisation_salarie,
|
|
0 AS montant_frais_imposables,
|
|
sum(montant_net_a_payer_salarie) AS montant_net_a_payer_salarie,
|
|
sum(montant_net_imposable_salarie) AS montant_net_imposable_salarie,
|
|
0 AS montant_od_net_salarie,
|
|
0 AS organisme_cotisation_id,
|
|
0 AS profil_id, -- p_historique_paie.profil_id,
|
|
(SELECT oid FROM rh.t_rubriques WHERE code = 'C000'),
|
|
0 as compte_id,
|
|
p_historique_paie.salarie_id,
|
|
0 AS taux_cotisation_patronale,
|
|
0 AS taux_cotisation_salarie
|
|
FROM rh.p_historique_paie
|
|
JOIN rh.p_salaries ON p_salaries.oid = p_historique_paie.salarie_id
|
|
GROUP BY 1,2,3,4,5,6,7,8,9, 18,19,20,21,22
|
|
) AS subq
|
|
JOIN rh.p_salaries ON p_salaries.oid = subq.salarie_id
|
|
JOIN w_totaux ON 1=1
|
|
AND w_totaux.matricule = p_salaries.matricule
|
|
AND w_totaux.date_debut = subq.date_debut
|
|
AND w_totaux.date_fin = subq.date_fin
|
|
GROUP BY 1,2,3,4,5,6,7,8,9, 18,19,20,21,22
|
|
HAVING 1!=1
|
|
OR sum(brut - subq.montant_brut) <> 0
|
|
OR sum(mt_pat - subq.montant_cotisation_patronale) <> 0
|
|
OR sum(mt_sal - subq.montant_cotisation_salarie) <> 0
|
|
OR sum(net_a_payer - subq.montant_net_a_payer_salarie) <> 0
|
|
OR sum(net_imposable - subq.montant_net_imposable_salarie) <> 0
|
|
;
|
|
|
|
/*
|
|
|
|
Quels sont les écarts cumulés > 0 ? :
|
|
|
|
SELECT
|
|
p_salaries.matricule,
|
|
p_historique_paie.*
|
|
FROM rh.p_historique_paie
|
|
JOIN rh.p_salaries on p_salaries.oid = p_historique_paie.salarie_id
|
|
JOIN rh.t_rubriques on t_rubriques.oid = p_historique_paie.rubrique_id
|
|
WHERE 1=1
|
|
AND t_rubriques.code_original = 'C000'
|
|
AND
|
|
(1!=1
|
|
OR p_historique_paie.base <> 0
|
|
OR p_historique_paie.montant_brut <> 0
|
|
OR p_historique_paie.montant_cotisation_salarie <> 0
|
|
OR p_historique_paie.montant_cotisation_patronale <> 0
|
|
OR p_historique_paie.montant_net_a_payer_salarie <> 0
|
|
OR p_historique_paie.montant_net_imposable_salarie <> 0
|
|
OR p_historique_paie.montant_avantage_nature <> 0
|
|
)
|
|
ORDER BY 1,4 DESC
|
|
;
|
|
|
|
*/
|
|
|
|
]]></sqlcmd>
|
|
</NODE>
|
|
<NODE label="Ventilation des profils">
|
|
<sqlcmd><![CDATA[
|
|
|
|
-- Alimentation des profils simultanés.
|
|
TRUNCATE rh.p_profil_contrat_mois
|
|
;
|
|
|
|
INSERT INTO rh.p_profil_contrat_mois (
|
|
profil_id,
|
|
contrat_mois_id,
|
|
salarie_id,
|
|
ratio,
|
|
mois
|
|
)
|
|
select
|
|
coalesce(w_profils.profil_id, 0) AS profil_id,
|
|
p_contrats_mois.oid as contrat_mois_id,
|
|
p_contrats_mois.salarie_id,
|
|
coalesce(w_ventilation.ratio, 1) AS ratio,
|
|
p_contrats_mois.mois_activite
|
|
from rh.p_contrats_mois
|
|
join rh.p_contrats ON p_contrats.oid = p_contrats_mois.contrat_id
|
|
left join w_profils ON 1=1
|
|
AND base.cti_overlaps(w_profils.date_debut,w_profils.date_fin,p_contrats_mois.date_debut,p_contrats_mois.date_fin)
|
|
--AND w_profils.date_debut = p_contrats_mois.date_debut
|
|
--AND w_profils.date_fin = p_contrats_mois.date_fin
|
|
AND w_profils.numero_contrat = p_contrats.numero_contrat
|
|
left join w_ventilation on 1=1
|
|
AND base.cti_overlaps(w_ventilation.date_debut,w_ventilation.date_fin,p_contrats_mois.date_debut,p_contrats_mois.date_fin)
|
|
--AND w_ventilation.date_debut = p_contrats_mois.date_debut
|
|
--AND w_ventilation.date_fin = p_contrats_mois.date_fin
|
|
AND w_ventilation.numero_contrat = p_contrats.numero_contrat
|
|
and w_ventilation.ventilation_id = w_profils.ventilation_id
|
|
group by 1,2,3,4,5
|
|
;
|
|
|
|
-- Correction des ratios != 1.
|
|
UPDATE rh.p_profil_contrat_mois
|
|
SET ratio = subq1.nv_ratio
|
|
FROM (
|
|
SELECT
|
|
p_profil_contrat_mois.profil_id,
|
|
p_profil_contrat_mois.contrat_mois_id,
|
|
p_profil_contrat_mois.ratio as anc_ratio,
|
|
ratio / ratio_total as nv_ratio
|
|
FROM rh.p_profil_contrat_mois
|
|
JOIN (
|
|
SELECT
|
|
contrat_mois_id,
|
|
sum(ratio) as ratio_total
|
|
FROM rh.p_profil_contrat_mois
|
|
GROUP BY 1
|
|
HAVING sum(ratio) != 1
|
|
) AS subq on subq.contrat_mois_id = p_profil_contrat_mois.contrat_mois_id
|
|
) AS subq1
|
|
WHERE 1=1
|
|
AND p_profil_contrat_mois.profil_id = subq1.profil_id
|
|
AND p_profil_contrat_mois.contrat_mois_id = subq1.contrat_mois_id
|
|
AND p_profil_contrat_mois.ratio = subq1.anc_ratio
|
|
AND p_profil_contrat_mois.mois < (SELECT max(mois) FROM w_paie_est_encours WHERE est_en_cours = 1) -- uniquement pour les mois clôturés.
|
|
;
|
|
|
|
-- @todo Calcul ETP théorique, Il faudra sans doute optimiser
|
|
WITH maj_etp AS (
|
|
SELECT
|
|
contrat_mois_id,
|
|
(CASE
|
|
WHEN type_temps_travail_id = 0 THEN 100
|
|
WHEN substr(type_temps_travail_code,1,1) IN ('C') THEN 100
|
|
WHEN base.cti_to_number(substr(type_temps_travail_code,2)) = 0 THEN 1
|
|
ELSE base.cti_to_number(substr(type_temps_travail_code,2))
|
|
END)::numeric AS pct_temps_travail,
|
|
(date_fin - date_debut + 1)::numeric AS duree,
|
|
(CASE date_part('month',date_fin)
|
|
WHEN 02 THEN CASE WHEN date_part('year',date_fin) IN (2000,2004,2008,2012) THEN 29 ELSE 28 END
|
|
WHEN 04 THEN 30
|
|
WHEN 06 THEN 30
|
|
WHEN 09 THEN 30
|
|
WHEN 11 THEN 30
|
|
ELSE 31
|
|
END)::numeric AS duree_mois
|
|
FROM rh.p_contrats_mois
|
|
JOIN rh.p_profil_contrat_mois ON p_profil_contrat_mois.contrat_mois_id = p_contrats_mois.oid
|
|
JOIN rh.p_profils ON p_profils.oid = p_profil_contrat_mois.profil_id)
|
|
UPDATE rh.p_contrats_mois SET
|
|
equivalent_temps_plein = round((duree / duree_mois) * (pct_temps_travail / 100.0), 7),
|
|
ratio_temps_travail = pct_temps_travail / 100.0
|
|
FROM maj_etp
|
|
WHERE 1=1
|
|
AND p_contrats_mois.oid = maj_etp.contrat_mois_id
|
|
AND (false
|
|
OR equivalent_temps_plein is not distinct from 0
|
|
OR ratio_temps_travail is not distinct from 0)
|
|
;
|
|
|
|
]]></sqlcmd>
|
|
</NODE>
|
|
<NODE label="Arrêts de travail">
|
|
<sqlcmd><![CDATA[
|
|
|
|
-- Création d'une table temporaire contenant 1 contrat pour 1 arret
|
|
DROP TABLE IF EXISTS w_arrets
|
|
;
|
|
|
|
CREATE TEMP TABLE w_arrets AS
|
|
with clustering as (
|
|
SELECT
|
|
pcn_salarie AS matricule,
|
|
pcn_typeconge AS motif,
|
|
to_char(pcn_datedebutabs,'YYYYMM')::numeric AS mois,
|
|
pcn_datedebutabs::date AS date_debut,
|
|
pcn_datefinabs::date AS date_fin,
|
|
pcn_datefinabs::date - pcn_datedebutabs::date + 1 AS nb_jours,
|
|
pcn_heures as nb_heures,
|
|
pci_salarie::text||lpad(pci_ordre,4,'0') AS numero_contrat,
|
|
case when lag(pcn_datefinabs) over w + '1 day'::interval = pcn_datedebutabs and lag(pcn_typeconge) over w = pcn_typeconge then null else true end as new_cluster
|
|
FROM prod_cegid.absencesalarie
|
|
JOIN prod_cegid.contrattravail ON 1=1
|
|
AND pci_salarie = pcn_salarie
|
|
AND base.cti_overlaps(pcn_datedebutabs::date,pcn_datefinabs::date,pci_debutcontrat::date, (CASE WHEN pci_fincontrat::date = '1900-01-01'::date THEN '2099-12-31' ELSE pci_fincontrat END)::date)
|
|
WHERE 1=1
|
|
AND pcn_typemvt = 'ABS'
|
|
AND pcn_mvtduplique != 'X'
|
|
and case when (SELECT length(trim(valeur)) > 0 FROM rh.t_divers WHERE code = 'IMP_INC_MAR') then pcn_typeconge IN (SELECT trim(unnest(string_to_array(valeur, ','))) FROM rh.t_divers WHERE code = 'IMP_INC_MAR') else true end
|
|
and pcn_typeconge NOT IN (SELECT trim(unnest(string_to_array(valeur, ','))) FROM rh.t_divers WHERE code = 'IMP_EXC_MAR')
|
|
window w as (partition by pcn_salarie order by pcn_datedebutabs)),
|
|
assigned_clustering as (
|
|
select
|
|
*,
|
|
count(new_cluster) over (
|
|
order by matricule, date_debut
|
|
rows unbounded preceding
|
|
) as cluster_id
|
|
from clustering)
|
|
select
|
|
matricule,
|
|
motif,
|
|
max(mois) AS mois,
|
|
min(date_debut) AS date_debut,
|
|
max(date_fin) AS date_fin,
|
|
sum(nb_jours) AS nb_jours,
|
|
sum(nb_heures) AS nb_heures,
|
|
max(numero_contrat) AS numero_contrat
|
|
from
|
|
assigned_clustering
|
|
group by matricule,motif, cluster_id
|
|
order by matricule, cluster_id
|
|
;
|
|
|
|
-- Alimentation des arrêts de travail
|
|
TRUNCATE rh.p_arrets_travail
|
|
;
|
|
|
|
ALTER SEQUENCE rh.s_arrets_travail RESTART WITH 1
|
|
;
|
|
|
|
INSERT INTO rh.p_arrets_travail(
|
|
salarie_id,
|
|
contrat_id,
|
|
mois_activite,
|
|
date_debut,
|
|
date_fin,
|
|
date_reprise,
|
|
motif_arret_id,
|
|
precision_motif_arret_id,
|
|
nb_jours,
|
|
nb_heures
|
|
)
|
|
SELECT p_salaries.oid,
|
|
p_contrats.oid,
|
|
w_arrets.mois,
|
|
w_arrets.date_debut,
|
|
w_arrets.date_fin,
|
|
(w_arrets.date_fin + INTERVAL '1 day')::date AS date_reprise,
|
|
t_motifs_arret.oid AS motif_arret_id,
|
|
0 AS precision_motif_arret_id,
|
|
w_arrets.nb_jours,
|
|
w_arrets.nb_heures
|
|
FROM w_arrets
|
|
JOIN rh.p_salaries ON p_salaries.matricule = w_arrets.matricule
|
|
JOIN rh.t_motifs_arret ON t_motifs_arret.code_original = w_arrets.motif
|
|
JOIN rh.p_contrats ON p_contrats.numero_contrat = w_arrets.numero_contrat
|
|
;
|
|
|
|
-- Ventilation mensuelle des arrêts de travail
|
|
TRUNCATE rh.p_arrets_travail_mois
|
|
;
|
|
|
|
INSERT INTO rh.p_arrets_travail_mois(
|
|
arret_travail_id,
|
|
salarie_id,
|
|
contrat_id,
|
|
contrat_mois_id,
|
|
mois_activite,
|
|
nb_debut_arret,
|
|
nb_fin_arret,
|
|
nb_reprise_apres_arret,
|
|
date_debut,
|
|
date_fin,
|
|
nb_jours,
|
|
nb_heures,
|
|
nb_arret
|
|
)
|
|
SELECT
|
|
p_arrets_travail.oid AS arret_travail_id,
|
|
p_arrets_travail.salarie_id AS salarie_id,
|
|
p_arrets_travail.contrat_id AS contrat_id,
|
|
(max(DISTINCT ARRAY[p_contrats_mois.date_fin - p_contrats_mois.date_debut, p_contrats_mois.oid]))[2] AS contrat_mois_id, -- On ratache l'arrêt au contrat le plus long dans le mois lorsque plusieurs contrat sur la même période.
|
|
p_contrats_mois.mois_activite,
|
|
CASE WHEN p_arrets_travail.date_debut BETWEEN min(p_contrats_mois.date_debut) AND max(p_contrats_mois.date_fin) THEN 1 ELSE 0 END AS nombre_debut_arret,
|
|
CASE WHEN p_arrets_travail.date_fin BETWEEN min(p_contrats_mois.date_debut) AND max(p_contrats_mois.date_fin) THEN 1 ELSE 0 END AS nombre_fin_arret,
|
|
0 AS nb_reprise_apres_arret,
|
|
min(GREATEST(p_contrats_mois.date_debut, p_arrets_travail.date_debut)) AS date_debut,
|
|
max(LEAST(p_contrats_mois.date_fin, p_arrets_travail.date_fin)) AS date_fin,
|
|
max(LEAST(p_contrats_mois.date_fin, p_arrets_travail.date_fin)::date) - min(GREATEST(p_contrats_mois.date_debut, p_arrets_travail.date_debut)::date) + 1 AS nb_jours,
|
|
(max(LEAST(p_contrats_mois.date_fin, p_arrets_travail.date_fin)::date) - min(GREATEST(p_contrats_mois.date_debut, p_arrets_travail.date_debut)::date) + 1)
|
|
* (base.cti_division(max(p_arrets_travail.nb_heures), max(p_arrets_travail.nb_jours))) as nb_heures,
|
|
1
|
|
FROM rh.p_contrats_mois
|
|
JOIN rh.p_arrets_travail ON 1=1
|
|
AND p_contrats_mois.contrat_id = p_arrets_travail.contrat_id
|
|
AND p_arrets_travail.date_debut <= p_contrats_mois.date_fin
|
|
AND p_arrets_travail.date_fin >= p_contrats_mois.date_debut
|
|
GROUP BY 1,2,3,5,p_arrets_travail.date_debut,p_arrets_travail.date_fin,p_arrets_travail.date_reprise
|
|
ORDER BY p_contrats_mois.mois_activite desc
|
|
;
|
|
|
|
update rh.p_arrets_travail_mois
|
|
set nb_reprise_apres_arret = subq.nb_reprise_apres_arret
|
|
from (
|
|
select
|
|
t1.arret_travail_id,
|
|
t1.mois_activite,
|
|
min(case when p_arrets_travail.date_reprise between t2.date_debut and t2.date_fin then 0 else 1 end) as nb_reprise_apres_arret
|
|
from rh.p_arrets_travail_mois as t1
|
|
join rh.p_arrets_travail ON p_arrets_travail.oid = t1.arret_travail_id
|
|
left join rh.p_arrets_travail_mois as t2 ON 1=1
|
|
AND t1.salarie_id = t2.salarie_id
|
|
AND t1.date_debut != t2.date_debut
|
|
AND t1.date_fin != t2.date_fin
|
|
GROUP BY t1.arret_travail_id, t1.mois_activite
|
|
order by 2 desc
|
|
) as subq
|
|
where 1=1
|
|
and p_arrets_travail_mois.arret_travail_id = subq.arret_travail_id
|
|
and p_arrets_travail_mois.mois_activite = subq.mois_activite
|
|
;
|
|
|
|
-- Ventilation journalière des arrêts de travail
|
|
/*
|
|
TRUNCATE rh.p_arrets_travail_jour
|
|
;
|
|
|
|
INSERT INTO rh.p_arrets_travail_jour(
|
|
arret_travail_id,
|
|
salarie_id,
|
|
contrat_id,
|
|
contrat_mois_id,
|
|
mois_activite,
|
|
est_debut_arret,
|
|
est_arret,
|
|
est_fin_arret,
|
|
est_reprise,
|
|
date
|
|
)
|
|
SELECT
|
|
p_arrets_travail.oid AS arret_travail_id,
|
|
p_arrets_travail.salarie_id AS salarie_id,
|
|
p_arrets_travail.contrat_id AS contrat_id,
|
|
contrat_mois_id,
|
|
p_calendrier.mois,
|
|
CASE WHEN p_arrets_travail.date_debut = p_calendrier.date THEN 1 ELSE 0 END AS est_debut_arret,
|
|
CASE WHEN p_calendrier.date BETWEEN p_arrets_travail.date_debut AND p_arrets_travail.date_fin THEN 1 ELSE 0 END AS est_arret,
|
|
CASE WHEN p_arrets_travail.date_fin = p_calendrier.date THEN 1 ELSE 0 END AS est_fin_arret,
|
|
CASE WHEN p_arrets_travail.date_reprise = p_calendrier.date THEN 1 ELSE 0 END AS est_reprise,
|
|
p_calendrier.date
|
|
FROM rh.p_arrets_travail
|
|
JOIN base.p_calendrier ON p_calendrier.date BETWEEN p_arrets_travail.date_debut AND p_arrets_travail.date_reprise
|
|
JOIN rh.p_arrets_travail_mois ON 1=1
|
|
AND p_arrets_travail_mois.arret_travail_id = p_arrets_travail.oid
|
|
AND p_arrets_travail_mois.mois_activite = p_calendrier.mois
|
|
GROUP BY 1,2,3,4,5,6,7,8,9,10
|
|
--ORDER BY 2, p_calendrier.date desc
|
|
;
|
|
*/
|
|
|
|
]]></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'
|
|
;
|
|
|
|
INSERT INTO rh.t_divers(
|
|
code,
|
|
texte,
|
|
valeur,
|
|
valeur_date,
|
|
description)
|
|
VALUES(
|
|
'MOIS_EN_COURS',
|
|
'Mois en cours (non clôturé).',
|
|
(SELECT mois FROM w_paie_est_encours WHERE est_en_cours = 1),
|
|
(SELECT (mois||'01')::date FROM w_paie_est_encours WHERE est_en_cours = 1),
|
|
'Mois en cours (non clôturé).'
|
|
)
|
|
;
|
|
|
|
]]></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>
|