You can not select more than 25 topics Topics must start with a letter or number, can include dashes ('-') and can be up to 35 characters long.
 
 
 

2270 lines
89 KiB

<?xml version="1.0" encoding="ISO-8859-1"?>
<ROOT>
<NODE name="INIT" label="INITIALISATIONS">
<NODE name="INIT" type="common" />
<NODE label="Mise à jour des informations permanentes">
<sqlcmd><![CDATA[
-- Màj des Entreprises
INSERT INTO rh.t_entreprises(code, texte, texte_court, code_original)
SELECT
ent.xcdreg,
ent.xlbpar,
substr(ent.xlbpar,1,50),
ent.xcdreg
FROM prod_shspub.pippub184_paramp AS fin
JOIN prod_shspub.pippub184_paramp AS ent ON ent.xcdreg = fin.xcdreg AND ent.xtyrad = 'CDBUD'
WHERE 1=1
AND fin.xtyrad = 'MNHETAB'
AND fin.xtxp01 = '340796358'
AND ent.xcdreg 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
substr(eta.xcdreg,3,2),
eta.xlbpar,
substr(eta.xlbpar,1,50),
substr(eta.xcdreg,3,2),
t_entreprises.oid
FROM prod_shspub.pippub184_paramp AS fin
JOIN prod_shspub.pippub184_paramp AS ent ON ent.xcdreg = fin.xcdreg AND ent.xtyrad = 'CDBUD'
JOIN prod_shspub.pippub184_paramp AS eta ON substr(eta.xcdreg,1,2) = ent.xcdreg AND eta.xtyrad = 'CDSBD'
JOIN rh.t_entreprises ON t_entreprises.code_original = ent.xcdreg
WHERE 1=1
AND fin.xtyrad = 'MNHETAB'
AND fin.xtxp01 = '340796358'
AND substr(eta.xcdreg,3,2) NOT IN (SELECT code_original FROM rh.t_etablissements)
GROUP BY 1,2,3,4,5
;
-- Màj des "Métiers" -- privé : "Catégories socio-professionnelles"
INSERT INTO rh.t_categories_socio_professionnelle(code, texte, texte_court, code_original)
SELECT hrpmet,hrplet,substr(hrplet,1,50),hrpmet
FROM prod_shspub.pippub184_hrpa1
WHERE hrpmet NOT IN (SELECT code_original FROM rh.t_categories_socio_professionnelle)
GROUP BY 1,2,3,4
;
-- Màj des "Sous-types de paie" -- privé : "Groupes de cotisants"
INSERT INTO rh.t_groupes_cotisant(code, texte, texte_court, code_original)
SELECT xcdsuf, xlbpar, substr(xlbpar,1,50), xcdsuf
FROM prod_shspub.pippub184_paramp
WHERE 1=1
AND xtyrad = 'SSPAY'
AND xcdsuf 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 xcdsuf, xcdsuf, xlbpar, substr(xlbpar,1,50)
FROM prod_shspub.pippub184_paramp
WHERE 1=1
AND xtyrad = 'MOENT'
AND xcdsuf != ''
AND xcdsuf IS NOT NULL
AND xcdsuf NOT IN (SELECT code_original FROM rh.t_motifs_debut_contrat)
GROUP BY 1,2,3,4
;
-- Màj des motifs de fin de contrat
INSERT INTO rh.t_motifs_fin_contrat(code, code_original, texte, texte_court)
SELECT xcdsuf, xcdsuf, xlbpar, substr(xlbpar,1,50)
FROM prod_shspub.pippub184_paramp
WHERE 1=1
AND xtyrad = 'MOSOR'
AND xcdsuf != ''
AND xcdsuf IS NOT NULL
AND xcdsuf NOT IN (SELECT code_original FROM rh.t_motifs_fin_contrat)
GROUP BY 1,2,3,4
;
-- Màj des "Nationalités" (Non renseigné == Nationalité française)
INSERT INTO rh.t_nationalites(code, code_original, texte, texte_court)
SELECT xcdsuf, xcdsuf, xlbpar, substr(xlbpar,1,50)
FROM prod_shspub.pippub184_paramp
WHERE 1=1
AND xtyrad = 'CDNAT'
AND xcdsuf != ''
AND xcdsuf IS NOT NULL
AND xcdsuf NOT IN (SELECT code_original FROM rh.t_nationalites)
GROUP BY 1,2,3,4
;
-- @TODO: Màj des "Créanciers" : privé : "Organismes de cotisation"
-- Màj des "Unités Fonctionnelles"
INSERT INTO rh.t_unite_fonctionnelle(code, texte, texte_court, code_original)
SELECT ufciuf, ufnmuf, substr(ufnmuf,1,50),ufciuf
FROM prod_shspub.pippub184_ufp01
WHERE 1=1
AND ufciuf NOT IN (SELECT code_original FROM rh.t_unite_fonctionnelle)
GROUP BY 1,2,3,4
;
-- Màj des "Rubriques"
INSERT INTO rh.t_rubriques(code, texte, texte_court, code_original, rang_edition)
SELECT
rcdrub,
rlbrub,
substr(rlbrub,1,50),
rcdrub,
(lpad(ascii(substr(rcdrub,1,1)),2,'0')
|| lpad(ascii(substr(rcdrub,2,1)),2,'0')
|| lpad(ascii(substr(rcdrub,3,1)),2,'0')
|| lpad(ascii(substr(rcdrub,4,1)),2,'0'))::numeric
FROM prod_shspub.pippub184_rbentp
WHERE rcdrub NOT IN (SELECT code_original FROM rh.t_rubriques)
GROUP BY 1,2,3,4,5
;
-- Màj des situations de famille
INSERT INTO rh.t_situations_famille(code, texte, texte_court, code_original)
SELECT xcdsuf, xlbpar, substr(xlbpar,1,50), xcdsuf
FROM prod_shspub.pippub184_paramp
WHERE 1=1
AND xtyrad = 'SIFAM'
AND xcdsuf NOT IN (SELECT code_original FROM rh.t_situations_famille)
GROUP BY 1,2,3,4
;
-- Màj des "Régimes statutaires" -- privé : "Types de contrat"
INSERT INTO rh.t_types_contrat(code, texte, texte_court, code_original)
SELECT xcdsuf, xlbpar, substr(xlbpar,1,50), xcdsuf
FROM prod_shspub.pippub184_paramp
WHERE 1=1
AND xtyrad = 'CDRGS'
AND xcdsuf NOT IN (SELECT code_original FROM rh.t_types_contrat)
GROUP BY 1,2,3,4
;
-- Màj des "Positions"-- privé : "Statuts"
INSERT INTO rh.t_statuts(code, texte, texte_court, code_original)
SELECT xcdsuf, xlbpar, substr(xlbpar,1,50), xcdsuf
FROM prod_shspub.pippub184_paramp
WHERE 1=1
AND xtyrad = 'CDPOS'
AND xcdsuf NOT IN (SELECT code_original FROM rh.t_statuts)
GROUP BY 1,2,3,4
;
-- Màj des types de temps de travail
INSERT INTO rh.t_types_temps_travail(code_original, code, texte, texte_court)
SELECT xcdsuf, xcdsuf, xlbpar, substr(xlbpar,1,50)
FROM prod_shspub.pippub184_paramp
WHERE 1=1
AND xtyrad = 'CDTRA'
AND xcdsuf NOT IN (SELECT code_original FROM rh.t_types_temps_travail)
GROUP BY 1,2,3,4
;
-- Màj des "Centres de Responsabilité" -- privé : "Services"
INSERT INTO rh.t_services(code_original, code, texte, texte_court)
SELECT rccicr, rccicr, rcli25, substr(rcli25,1,50)
FROM prod_shspub.pippub184_rcp01pp
WHERE 1=1
AND rccicr NOT IN (SELECT code_original FROM rh.t_services)
GROUP BY 1,2,3,4
;
/* SAUVEGARDE de services potentiels
SELECT umcser, umcser, umnser, substr(umnser,1,50)
FROM prod_shspub.pippub184_ump01pp
WHERE 1=1
AND umcser NOT IN (SELECT code_original FROM rh.t_services)
GROUP BY 1,2,3,4
*/
-- Màj des "Lettres Budgétaires"
INSERT INTO rh.t_lettre_budgetaire(code_original, code, texte, texte_court)
SELECT lblbud, lblbud, lbli40, substr(lbli40,1,50)
FROM prod_shspub.pippub184_lbp01
WHERE 1=1
AND lblbud NOT IN (SELECT code_original FROM rh.t_lettre_budgetaire)
GROUP BY 1,2,3,4
;
-- Màj des "Types de paie" -- privé : "Codes emploi"
INSERT INTO rh.t_codes_emploi(code_original, texte, texte_court, code)
SELECT xcdsuf, xlbpar, substr(xlbpar,1,50), xcdsuf
FROM prod_shspub.pippub184_paramp
WHERE 1=1
AND xtyrad = 'TYPAY'
AND xcdsuf NOT IN (SELECT code_original FROM rh.t_codes_emploi)
GROUP BY 1,2,3,4
;
-- Màj des types d'horaire
INSERT INTO rh.t_types_horaire(code_original, code, texte, texte_court)
SELECT
htyhor,
htyhor,
hlbtyp,
substr(hlbtyp,1,50)
FROM prod_shspub.pippub184_tyhorp
WHERE 1=1
AND htyhor NOT IN (SELECT code_original FROM rh.t_types_horaire)
AND htyhor != ''
GROUP BY 1,2,3,4
;
-- Màj des "Groupes de commission paritaire"
INSERT INTO rh.t_commission_paritaire(code, texte, texte_court, code_original)
SELECT xcdsuf, xlbpar, substr(xlbpar,1,50), xcdsuf
FROM prod_shspub.pippub184_paramp
WHERE 1=1
AND xtyrad = 'CDGCP'
AND xcdsuf NOT IN (SELECT code_original FROM rh.t_commission_paritaire)
GROUP BY 1,2,3,4
;
-- Màj des grilles (grades)
INSERT INTO rh.t_grilles(code_original, code, texte, texte_court)
SELECT dcdgrd, dcdgrd, dlbgrd, substr(dlbgrd,1,50)
FROM prod_shspub.pippub184_gdentp
WHERE 1=1
AND dcdgrd NOT IN (SELECT code_original FROM rh.t_grilles)
GROUP BY 1,2,3,4
;
-- Màj des groupes de grilles (échelons)
INSERT INTO rh.t_grilles_groupes(code_original, code, texte, texte_court)
SELECT acdech, acdech, acdech, substr(acdech,1,50)
FROM prod_shspub.pippub184_agavap
WHERE 1=1
AND acdech NOT IN (SELECT code_original FROM rh.t_grilles_groupes)
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 mcdmot, mcdmot, mlbmot, substr(mlbmot,1,50)
FROM prod_shspub.pippub184_motifp
WHERE 1=1
AND mcdmot NOT IN (SELECT code_original FROM rh.t_motifs_arret)
GROUP BY 1,2,3,4
;
-- @TODO: Màj des précisions du motif d'arrêt
-- @TODO: Màj des "Types de visite médicale" : privé : "Motifs de visite médicale"
-- Màj des "Causes d'accident du travail" -- privé : "Circonstances d'accident du travail"
INSERT INTO rh.t_accident_circonstance(code_original, texte, texte_court, code)
SELECT xcdsuf, max(xlbpar), max(substr(xlbpar,1,50)), xcdsuf
FROM prod_shspub.pippub184_paramp
WHERE 1=1
AND xtyrad = 'ABCOMPL'
AND xcdsuf NOT IN (SELECT code_original FROM rh.t_accident_circonstance)
GROUP BY 1,4
;
-- Màj des "Conséquences d'accident du travail" -- privé : "Lieux d'accident du travail"
INSERT INTO rh.t_accident_lieu(code_original, texte, texte_court, code)
SELECT xcdsuf, max(xlbpar), max(substr(xlbpar,1,50)), xcdsuf
FROM prod_shspub.pippub184_paramp
WHERE 1=1
AND xtyrad = 'ABSUPPL'
AND xcdsuf NOT IN (SELECT code_original FROM rh.t_accident_lieu)
GROUP BY 1,4
;
-- @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 "Comptes d'Imputation"
INSERT INTO rh.t_compte(code_original, code, texte, texte_court)
SELECT icdcha, icdcha, ilbimp, substr(ilbimp,1,50)
FROM prod_shspub.pippub184_imputp
WHERE icdcha NOT IN (SELECT code_original FROM rh.t_compte)
GROUP BY 1,2,3,4
;
-- Màj des "Catégories de congé"
INSERT INTO rh.t_categorie_conge(code_original, code, texte, texte_court)
SELECT ccdcat, ccdcat, clbcat, substr(clbcat,1,50)
FROM prod_shspub.pippub184_categp
WHERE ccdcat NOT IN (SELECT code_original FROM rh.t_categorie_conge)
GROUP BY 1,2,3,4
;
-- Màj des "Cadres d'emploi"
INSERT INTO rh.t_cadre_emploi(code_original, code, texte, texte_court)
SELECT kcdcem, kcdcem, klbcem, substr(klbcem,1,50)
FROM prod_shspub.pippub184_ceentp
WHERE kcdcem NOT IN (SELECT code_original FROM rh.t_cadre_emploi)
GROUP BY 1,2,3,4
;
-- Màj des "Filières"
INSERT INTO rh.t_filiere(code_original, code, texte, texte_court)
SELECT kcdfil, kcdfil, klbfil, substr(klbfil,1,50)
FROM prod_shspub.pippub184_fientp
WHERE kcdfil NOT IN (SELECT code_original FROM rh.t_filiere)
GROUP BY 1,2,3,4
;
-- Màj des "Catégories statutaires"
INSERT INTO rh.t_categorie_statutaire(code, texte, texte_court, code_original)
SELECT xcdsuf, xlbpar, substr(xlbpar,1,50), xcdsuf
FROM prod_shspub.pippub184_paramp
WHERE 1=1
AND xtyrad = 'CDCAS'
AND xcdsuf NOT IN (SELECT code_original FROM rh.t_categorie_statutaire)
GROUP BY 1,2,3,4
;
-- Màj des "Codes cotisation"
INSERT INTO rh.t_code_cotisation(code, texte, texte_court, code_original)
SELECT xcdsuf, xlbpar, substr(xlbpar,1,50), xcdsuf
FROM prod_shspub.pippub184_paramp
WHERE 1=1
AND xtyrad = 'CDCOT'
AND xcdsuf NOT IN (SELECT code_original FROM rh.t_code_cotisation)
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
entreprise_id,
etablissement_id,
mois,
count(DISTINCT matricule),
sum(montant_brut),
sum(nombre_heures)
FROM
(
SELECT
t_entreprises.oid AS entreprise_id,
t_etablissements.oid AS etablissement_id,
ommtrt AS mois,
ocdagt AS matricule,
sum(CASE WHEN ocdrub = '499' THEN omtcal ELSE 0 END) AS montant_brut,
/*sum(
CASE WHEN ocdrub < '499'
THEN omtcal
ELSE 0
END * CASE WHEN redipd = 'D' THEN -1 ELSE 1 END
) AS montant_brut,*/
sum(CASE WHEN ocdrub = '005' THEN omtcal ELSE 0 END) AS nombre_heures
FROM prod_shspub.pippub184_histop AS hp
--JOIN prod_shspub.pippub184_rbentp AS rb ON rb.rcdrub = hp.ocdrub
JOIN rh.t_entreprises ON t_entreprises.code_original = hp.ocdbud
JOIN rh.t_etablissements ON t_etablissements.code_original = hp.ocdsbd
WHERE 1=1
AND ommtrt >= 200901
AND ocdrub IN ('005', '499')
AND ocdagt != '101413' -- Fiche Régime-Imputation incohérente au niveau des dates, agent en Fin de Contrat
GROUP BY 1,2,3,4
HAVING sum(CASE WHEN ocdrub = '499' THEN omtcal ELSE 0 END) != 0
) AS subq
GROUP BY 1,2,3
;
]]></sqlcmd>
</NODE>
<NODE label="Pre-traitements">
<sqlcmd><![CDATA[
-- Création table temp spéciale Entreprise/Etablissement
DROP TABLE IF EXISTS w_finess
;
CREATE TEMP TABLE w_finess AS
SELECT
substr(eta.xcdreg,3,2) AS eta_code,
ent.xcdreg AS ent_code,
t_entreprises.oid AS entreprise_id,
t_etablissements.oid AS etablissement_id,
fin.xtxp01 AS finess
FROM prod_shspub.pippub184_paramp AS fin
JOIN prod_shspub.pippub184_paramp AS ent ON ent.xcdreg = fin.xcdreg AND ent.xtyrad = 'CDBUD'
JOIN prod_shspub.pippub184_paramp AS eta ON substr(eta.xcdreg,1,2) = ent.xcdreg AND eta.xtyrad = 'CDSBD'
JOIN rh.t_entreprises ON t_entreprises.code_original = ent.xcdreg
JOIN rh.t_etablissements ON t_etablissements.code_original = substr(eta.xcdreg,3,2)
WHERE 1=1
AND fin.xtyrad = 'MNHETAB'
AND fin.xtxp01 = '340796358'
GROUP BY 1,2,3,4,5
;
-- Création d'une table d'association historisée grade<=>infos diverses
DROP TABLE IF EXISTS w_grade_divers
;
CREATE TEMP TABLE w_grade_divers AS
SELECT
dcdgrd AS grade,
ddtinf AS date_debut,
CASE
WHEN ddsinf = 'O' THEN '20991231'
ELSE (SELECT to_char(to_date(min(ddtinf), 'YYYYMMDD') - '1 day'::interval, 'YYYYMMDD')::numeric FROM prod_shspub.pippub184_gdinfp AS sq WHERE sq.dcdgrd = gdinfp.dcdgrd AND sq.ddtinf > gdinfp.ddtinf)
END AS date_fin,
dcdgcp, -- commission_paritaire,
dcdcem, -- cadre_emploi,
dcdfil, -- filiere,
dcdcas -- categorie_statutaire
FROM prod_shspub.pippub184_gdinfp AS gdinfp
WHERE 1=1
AND dcdgrd != ''
ORDER BY 1, 2
;
-- Création d'une table d'association grade<=>métier
DROP TABLE IF EXISTS w_grade_metier
;
CREATE TEMP TABLE w_grade_metier AS
SELECT
xcdsuf AS grade,
xlbpar AS metier
FROM prod_shspub.pippub184_paramp
WHERE xtyrad = 'MET_GRD'
;
-- Création d'une table avec le dernier historique de la fiche cotisation par agent
DROP TABLE IF EXISTS w_cotisation
;
CREATE TEMP TABLE w_cotisation AS
SELECT
acdagt AS matricule,
acdbud AS ent,
acdsbd AS eta,
atycot AS code_cotisation,
amatre AS matricule_retraite
FROM prod_shspub.pippub184_agcotp
WHERE 1=1
AND aamfco = 20991231
AND acdsbd = (SELECT eta_code FROM w_finess)
AND acdbud = (SELECT ent_code FROM w_finess)
;
-- Création de la table de correspondance Rubrique <=> Régime Statutaire <=> Compte d'imputation.
-- Utilisée pour la paye uniquement (associer une rubrique à un compte).
DROP TABLE IF EXISTS w_cor
;
CREATE TEMP TABLE w_cor AS
SELECT
rcdrub AS rubrique,
rcdbud AS entreprise,
rcdsbd AS etablissement,
rcdrgs AS statut, -- Régime statutaire
rcdcha AS compte -- Compte d'imputation
FROM prod_shspub.pippub184_rbimpp
JOIN rh.t_types_contrat ON t_types_contrat.code_original = pippub184_rbimpp.rcdrgs
WHERE 1=1
AND rcdsbd IN (SELECT eta_code FROM w_finess)
AND rcdbud IN (SELECT ent_code FROM w_finess)
AND t_types_contrat.oid > 0
ORDER BY 1,4,5 DESC
;
UPDATE w_cor
SET compte = subq.rcdcha
FROM (
SELECT
rcdrub,
rcdcha
FROM prod_shspub.pippub184_rbimpp
WHERE 1=1
AND rcdsbd = ''
AND rcdbud =''
AND rcdcha != ''
) AS subq
WHERE 1=1
AND rubrique = subq.rcdrub
AND compte = ''
;
-- Création d'un table avec les "éléments variables" saisis par salariés
DROP TABLE IF EXISTS w_ev
;
CREATE TEMP TABLE w_ev AS
SELECT
ecdagt AS agent,
ecdbud AS entreprise,
ecdsbd AS etablissement,
ecdrub AS rubrique,
to_date(edtdeb,'YYYYMMDD') AS date_debut,
(CASE WHEN edtfin != 20991231
THEN to_date(edtfin,'YYYYMMDD')
ELSE to_date(edtdeb,'YYYYMMDD') + interval '1 month' - interval '1 day' END
)::date AS date_fin,
substr(edtdeb, 1, 6) AS mois,
ecdbax AS lettre_budgetaire_code_original,
ecdser AS service_code_original,
ecduf AS unite_fonctionnelle_code_original
FROM prod_shspub.pippub184_elagtp
WHERE 1=1
AND ecduf != ''
AND ecdbud IN (SELECT ent_code FROM w_finess)
AND ecdsbd IN (SELECT eta_code FROM w_finess)
;
]]></sqlcmd>
</NODE>
<NODE label="Pre-traitement des Profils">
<sqlcmd><![CDATA[
-- Création d'un table temp de profils
DROP TABLE IF EXISTS w_profils
;
CREATE TEMP TABLE w_profils AS
SELECT
-- Infos d'identification du profil
0 AS profil_id,
0 AS encours, -- dernier profil du matricule (1=oui, 0=non)
av.acdagt AS agent,
av.acdsbd AS eta,
av.acdbud AS ent,
av.acdagt||greatest(av.adtpec, tp.adttps, ho.adthor, ri.adtimp, pa.adtpay, wgd.date_debut) AS numero_situation,
to_date(greatest(av.adtpec, tp.adttps, ho.adthor, ri.adtimp, pa.adtpay, wgd.date_debut),'YYYYMMDD') AS date_debut,
to_date(least(av.adtfpc, tp.adtftp, ho.hofhor, ri.imftim, pa.adtfpa, wgd.date_fin),'YYYYMMDD') AS date_fin,
tp.anbhrm AS nb_h, -- Nombre d'heures payees theoriques
(
base.cti_division(ANUTP1,ADETP1)
+
base.cti_division(ANUTP2,ADETP2)
+
base.cti_division(ANUTP3,ADETP3)
+
base.cti_division(ANUTP4,ADETP4)
+
base.cti_division(ANUTP5,ADETP5)
) * CASE WHEN ANBHRM <> 0 THEN 1 ELSE 0 END AS etp_theorique,
base.cti_unnest3(array[anbse1,anbse2,anbse3,anbse4,anbse5]) / 100 AS pct, -- Pourcentage d'affectation
base.cti_unnest3(array[
CASE WHEN anbse1 > 0 THEN 1 ELSE NULL END,
CASE WHEN anbse2 > 0 THEN 2 ELSE NULL END,
CASE WHEN anbse3 > 0 THEN 3 ELSE NULL END,
CASE WHEN anbse4 > 0 THEN 4 ELSE NULL END,
CASE WHEN anbse5 > 0 THEN 5 ELSE NULL END
]) AS rang, -- Rang d'affectation
to_date(ag.adtent, 'YYYYMMDD') AS date_entree_ets,
-- Codes originaux
greatest(w_grade_metier.metier,chr(1)||'*') AS categorie_socio_professionnelle_code_original, -- Métier
greatest(pa.aagtyp,chr(1)||'*') AS code_emploi_code_original, -- Type de paie
greatest(av.acdgrd,chr(1)||'*') AS grille_code_original, -- Grade
greatest(av.acdech,chr(1)||'*') AS grille_groupe_code_original, -- Echelon
greatest(pa.asspay,chr(1)||'*') AS groupe_cotisant_code_original, -- Sous-type de paie
greatest(ag.amoent,chr(1)||'*') AS motif_debut_code_original, -- Motif debut d'entree ets
greatest(ag.amosor,chr(1)||'*') AS motif_fin_code_original, -- Motif sortie ets
base.cti_unnest2(array[acduf1,acduf2,acduf3,acduf4,acduf5]) AS unite_fonctionnelle_code_original, -- UF
greatest(ho.acdcat,chr(1)||'*') AS categorie_conge_code_original, -- Catégorie congé
greatest(ri.acdcha,chr(1)||'*') AS compte_salarie_code_original, -- Compte d'imputation
base.cti_unnest2(array[acdse1,acdse2,acdse3,acdse4,acdse5]) AS service_code_original, -- CR
greatest(wgd.dcdgcp,chr(1)||'*') AS commission_paritaire_code_original, -- Groupe de commission paritaire
base.cti_unnest2(array[acdax1,acdax2,acdax3,acdax4,acdax5]) AS lettre_budgetaire_code_original, -- Lettre budgétaire
greatest(pa.pacpos,chr(1)||'*') AS statut_code_original, -- Position
greatest(ri.acdrgs,chr(1)||'*') AS type_contrat_code_original, -- Régime statutaire
greatest(ho.atyhor,chr(1)||'*') AS type_horaire_code_original, -- Idem
greatest(tp.acdtra,chr(1)||'*') AS type_temps_travail_code_original, -- Type de contrat
greatest(wgd.dcdcem,chr(1)||'*') AS cadre_emploi_code_original, -- Cadre emploi
greatest(wgd.dcdfil,chr(1)||'*') AS filiere_code_original, -- Filiere
greatest(wgd.dcdcas,chr(1)||'*') AS categorie_statutaire_code_original, -- Categorie statutaire
(chr(1)||'*')::text AS qualification_code_original,
(chr(1)||'*')::text AS section_analytique_code_original,
(chr(1)||'*')::text AS section_analytique_paie_code_original,
(chr(1)||'*')::text AS societe_interim_code_original,
(chr(1)||'*')::text AS specialite_code_original
FROM prod_shspub.pippub184_agentp AS ag
-- Fiche "Avancement"
LEFT JOIN prod_shspub.pippub184_agavap AS av ON 1=1
AND av.acdagt = ag.acdagt
-- Fiche "Temps-effectif-service"
LEFT JOIN prod_shspub.pippub184_agtpsp AS tp ON 1=1
AND tp.acdagt = av.acdagt
AND tp.acdsbd = av.acdsbd
AND tp.acdbud = av.acdbud
AND base.cti_overlaps(to_date(av.adtpec, 'YYYYMMDD'), to_date(av.adtfpc, 'YYYYMMDD'), to_date(tp.adttps, 'YYYYMMDD'), to_date(tp.adtftp, 'YYYYMMDD'))
-- Fiche "Horaire"
LEFT JOIN prod_shspub.pippub184_aghorp AS ho ON 1=1
AND ho.acdagt = av.acdagt
AND ho.acdsbd = av.acdsbd
AND ho.acdbud = av.acdbud
AND base.cti_overlaps(to_date(av.adtpec, 'YYYYMMDD'), to_date(av.adtfpc, 'YYYYMMDD'), to_date(ho.adthor, 'YYYYMMDD'), to_date(ho.hofhor, 'YYYYMMDD'))
AND base.cti_overlaps(to_date(tp.adttps, 'YYYYMMDD'), to_date(tp.adtftp, 'YYYYMMDD'), to_date(ho.adthor, 'YYYYMMDD'), to_date(ho.hofhor, 'YYYYMMDD'))
-- Fiche "Imputation-régime"
LEFT JOIN prod_shspub.pippub184_agimpp AS ri ON 1=1
AND ri.acdagt = av.acdagt
AND ri.acdsbd = av.acdsbd
AND ri.acdbud = av.acdbud
AND base.cti_overlaps(to_date(av.adtpec, 'YYYYMMDD'), to_date(av.adtfpc, 'YYYYMMDD'), to_date(ri.adtimp, 'YYYYMMDD'), to_date(ri.imftim, 'YYYYMMDD'))
AND base.cti_overlaps(to_date(tp.adttps, 'YYYYMMDD'), to_date(tp.adtftp, 'YYYYMMDD'), to_date(ri.adtimp, 'YYYYMMDD'), to_date(ri.imftim, 'YYYYMMDD'))
AND base.cti_overlaps(to_date(ho.adthor, 'YYYYMMDD'), to_date(ho.hofhor, 'YYYYMMDD'), to_date(ri.adtimp, 'YYYYMMDD'), to_date(ri.imftim, 'YYYYMMDD'))
-- Fiche "Type de paye"
LEFT JOIN prod_shspub.pippub184_agpayp AS pa ON 1=1
AND pa.acdagt = av.acdagt
AND pa.acdsbd = av.acdsbd
AND pa.acdbud = av.acdbud
AND base.cti_overlaps(to_date(av.adtpec, 'YYYYMMDD'), to_date(av.adtfpc, 'YYYYMMDD'), to_date(pa.adtpay, 'YYYYMMDD'), to_date(pa.adtfpa, 'YYYYMMDD'))
AND base.cti_overlaps(to_date(tp.adttps, 'YYYYMMDD'), to_date(tp.adtftp, 'YYYYMMDD'), to_date(pa.adtpay, 'YYYYMMDD'), to_date(pa.adtfpa, 'YYYYMMDD'))
AND base.cti_overlaps(to_date(ho.adthor, 'YYYYMMDD'), to_date(ho.hofhor, 'YYYYMMDD'), to_date(pa.adtpay, 'YYYYMMDD'), to_date(pa.adtfpa, 'YYYYMMDD'))
AND base.cti_overlaps(to_date(ri.adtimp, 'YYYYMMDD'), to_date(ri.imftim, 'YYYYMMDD'), to_date(pa.adtpay, 'YYYYMMDD'), to_date(pa.adtfpa, 'YYYYMMDD'))
-- "Fichier grades (informations diverses)"
LEFT JOIN w_grade_divers AS wgd ON 1=1
AND wgd.grade = av.acdgrd
AND base.cti_overlaps(to_date(av.adtpec, 'YYYYMMDD'), to_date(av.adtfpc, 'YYYYMMDD'), to_date(wgd.date_debut, 'YYYYMMDD'), to_date(wgd.date_fin, 'YYYYMMDD'))
AND base.cti_overlaps(to_date(tp.adttps, 'YYYYMMDD'), to_date(tp.adtftp, 'YYYYMMDD'), to_date(wgd.date_debut, 'YYYYMMDD'), to_date(wgd.date_fin, 'YYYYMMDD'))
AND base.cti_overlaps(to_date(ho.adthor, 'YYYYMMDD'), to_date(ho.hofhor, 'YYYYMMDD'), to_date(wgd.date_debut, 'YYYYMMDD'), to_date(wgd.date_fin, 'YYYYMMDD'))
AND base.cti_overlaps(to_date(ri.adtimp, 'YYYYMMDD'), to_date(ri.imftim, 'YYYYMMDD'), to_date(wgd.date_debut, 'YYYYMMDD'), to_date(wgd.date_fin, 'YYYYMMDD'))
AND base.cti_overlaps(to_date(pa.adtpay, 'YYYYMMDD'), to_date(pa.adtfpa, 'YYYYMMDD'), to_date(wgd.date_debut, 'YYYYMMDD'), to_date(wgd.date_fin, 'YYYYMMDD'))
LEFT JOIN w_grade_metier ON w_grade_metier.grade = av.acdgrd
WHERE 1=1
--AND av.acdagt = '100017'
AND av.acdagt NOT IN ('101413','101478') -- @TODO Fiche Régime-Imputation incohérente au niveau des dates, agent en Fin de Contrat
AND afipay = 1
AND ag.adtent != 0 -- Uniquement les agents qui ont une date d'entrée dans l'établissement
--AND av.adtpec >= ag.adtent -- Uniquement l'historique depuis l'entrée dans l'établissement
AND av.acdsbd = (SELECT eta_code FROM w_finess)
AND av.acdbud = (SELECT ent_code FROM w_finess)
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
--order by 6 desc
;
]]></sqlcmd>
</NODE>
<NODE name="PROFIL" type="common" />
<NODE label="Post-traitement des Profils">
<sqlcmd><![CDATA[
-- On conserve tous les profils dans w_profils_all.
DROP TABLE IF EXISTS w_profils_all
;
CREATE TEMP TABLE w_profils_all AS
SELECT *
FROM w_profils
;
DROP TABLE w_profils
;
-- Sauvegarde de l'historique complet des profils.
DROP TABLE IF EXISTS w_profil_sav
;
CREATE TEMP TABLE w_profil_sav AS
SELECT *
FROM w_profils_all
;
-- Suppression des profils qui sont avant la date d'entrée dans l'établissement.
DELETE FROM w_profils_all
WHERE date_fin <= date_entree_ets
;
-- Màj de la date de fin du dernier profil d'un agent
-- 1. Cas où la date de sortie de l'agent est supérieure à la date de début de son dernier profil
UPDATE w_profils_all
SET date_fin = to_date(agent.adtsor,'YYYYMMDD')
FROM prod_shspub.pippub184_agentp AS agent
WHERE 1=1
AND agent.acdagt = w_profils_all.agent
AND agent.adtsor != 0
AND w_profils_all.date_fin = '2099-12-31'
AND w_profils_all.date_debut <= to_date(agent.adtsor,'YYYYMMDD')
;
-- 2. Cas où la date de sortie de l'agent est inférieure à la date de début de son dernier profil
-- a. sauvegarde des agents ayant cette caractéristique
DROP TABLE IF EXISTS w_tmp
;
CREATE TEMP TABLE w_tmp AS
SELECT
w_profils_all.agent,
to_date(agent.adtsor,'YYYYMMDD') AS date_sortie
FROM w_profils_all
JOIN prod_shspub.pippub184_agentp AS agent ON agent.acdagt = w_profils_all.agent
WHERE 1=1
AND agent.adtsor != 0
GROUP BY 1,2
HAVING max(date_fin) = '2099-12-31'
;
-- b. suppression des profils qui vont au-delà de la date de sortie de l'agent
DELETE FROM w_profils_all
USING prod_shspub.pippub184_agentp AS agent
WHERE 1=1
AND agent.acdagt = w_profils_all.agent
AND agent.adtsor != 0
--AND w_profils_all.date_fin = '2099-12-31'
AND w_profils_all.date_debut > to_date(agent.adtsor,'YYYYMMDD')
;
-- c. màj des date de fin du dernier profil de l'agent <= date de sortie de l'agent
UPDATE w_profils_all
SET date_fin = subq.date_sortie
FROM
(
SELECT
w_profils_all.agent,
max(w_profils_all.date_debut) AS date_debut,
w_tmp.date_sortie
FROM w_profils_all
JOIN w_tmp ON w_tmp.agent = w_profils_all.agent
GROUP BY 1,3
) AS subq
WHERE 1=1
AND subq.agent = w_profils_all.agent
AND subq.date_debut = w_profils_all.date_debut
;
-- Identification des derniers profils des matricule (champ "encours")
-- SELECT * FROM w_profils_all WHERE encours = 1
UPDATE w_profils_all
SET encours = 1
FROM
(
SELECT
w_profils_all.agent,
max(w_profils_all.date_debut) AS date_debut
FROM w_profils_all
GROUP BY 1
) AS subq
WHERE 1=1
AND subq.agent = w_profils_all.agent
AND subq.date_debut = w_profils_all.date_debut
;
-- Optimisation de w_profils_all
SELECT base.cti_optimize_table('w_profils_all')
;
-- Création d'un table de profil avec 1 seul profil par matricule simultané.
CREATE TEMP TABLE w_profils AS
SELECT *
FROM w_profils_all
WHERE rang = 1
;
]]></sqlcmd>
</NODE>
<NODE label="Salariés">
<sqlcmd><![CDATA[
-- On ne supprime plus les salariés car on peut créer des listes/classes basées dessus.
DROP TABLE IF EXISTS w_salaries
;
CREATE TEMP TABLE w_salaries AS
SELECT
'[FINESS]' AS finess,
CASE WHEN anmmar != '' THEN anmmar ELSE anmnai END AS nom,
aprnma AS prenom,
CASE WHEN to_date(adtnai, 'YYYYMMDD') BETWEEN '1900-01-01'::date AND now()::date
THEN to_date(adtnai, 'YYYYMMDD')
ELSE '1962-04-14'::date
END AS date_naissance,
agent.acdsxa AS sexe,
agent.acdagt AS matricule,
agent.acdagt AS code,
agent.acdagt AS code_original,
(SELECT entreprise_id FROM w_finess) AS entreprise_id,
coalesce(t_nationalites.oid, 0) AS nationalite_id,
coalesce(t_codes_postaux.oid, 0) AS code_postal_id,
anmnai AS nom_naissance,
coalesce(t_situations_famille.oid,0) AS situation_famille_id, -- asifam (M,V,C,D,...)
w_profils.profil_id AS profil_id,
to_date(adtent, 'YYYYMMDD') AS date_debut,
CASE WHEN adtent > adtsor THEN '2099-12-31'::date ELSE to_date(adtsor, 'YYYYMMDD') END AS date_fin,
to_date(agent.adtent, 'YYYYMMDD') AS date_entree_ets,
CASE WHEN agent.adtadm = 0
THEN to_date(agent.adtent, 'YYYYMMDD')
ELSE to_date(agent.adtadm, 'YYYYMMDD')
END AS date_entree_fp,
CASE WHEN agent.agdfph = 0
THEN to_date(agent.adtent, 'YYYYMMDD')
ELSE to_date(agent.agdfph, 'YYYYMMDD')
END AS date_entree_fph,
cp.aadeli AS no_adeli,
coalesce(t_code_cotisation.oid, 0) AS code_cotisation_id,
matricule_retraite
FROM prod_shspub.pippub184_agentp AS agent
LEFT JOIN prod_shspub.pippub184_agencp AS cp ON cp.acdagt = agent.acdagt
LEFT JOIN rh.t_codes_postaux ON t_codes_postaux.code = agent.aadpos
LEFT JOIN rh.t_situations_famille ON t_situations_famille.code_original = agent.asifam
LEFT JOIN w_cotisation ON w_cotisation.matricule = agent.acdagt
LEFT JOIN rh.t_code_cotisation ON t_code_cotisation.code_original = w_cotisation.code_cotisation
LEFT JOIN rh.t_nationalites ON t_nationalites.code_original = agent.acdnat
JOIN w_profils ON 1=1
AND encours = 1
AND w_profils.agent = agent.acdagt
WHERE 1=1
AND aprnma != ''
AND agent.adtent != 0 -- Uniquement les agents qui ont une date d'entrée dans l'établissement
GROUP BY 1,2,3,4,5,6,7,8,9,10,11,12,13,14,15,16,17,18,19,20,21,22
;
]]></sqlcmd>
</NODE>
<NODE name="SALARIE" type="common" />
<NODE label="Contrats">
<sqlcmd><![CDATA[
-- Peuplement des contrats.
TRUNCATE rh.p_contrats
;
ALTER SEQUENCE rh.s_contrats RESTART WITH 1
;
INSERT INTO rh.p_contrats(
numero_contrat,
code_original,
salarie_id,
etablissement_id,
date_debut,
date_fin,
profil_id
)
SELECT
w_profils.numero_situation AS numero_situation,
w_profils.numero_situation AS code_original,
coalesce(p_salaries.oid,0) AS salarie_id,
coalesce(t_etablissements.oid,0) AS etablissement_id,
w_profils.date_debut AS date_debut,
w_profils.date_fin AS date_fin,
max(p_profils.oid) AS profil_id
-- On prend le max arbitrairement pour corriger un doublon sur numero_situation = '10198520141020' uniquement.
FROM w_profils
JOIN rh.p_salaries on p_salaries.matricule = w_profils.agent
JOIN rh.t_etablissements ON t_etablissements.code_original = w_profils.eta
JOIN rh.p_profils ON p_profils.oid = w_profils.profil_id
WHERE 1=1
AND w_profils.eta = (SELECT eta_code FROM w_finess)
AND w_profils.ent = (SELECT ent_code FROM w_finess)
GROUP BY 1,2,3,4,5,6
;
-- Màj des contrats ventilés mensuellement
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,
profil_id,
nombre_debut_contrat,
nombre_fin_contrat,
equivalent_temps_plein,
age_id,
age_jours,
est_hors_periode,
present_fin_mois,
anciennete_mois,
anciennete_annee_id,
anciennete_fp_mois,
anciennete_fp_annee_id,
anciennete_fph_mois,
anciennete_fph_annee_id
)
SELECT
p_salaries.oid,
p_contrats.oid AS contrat_id,
p_calendrier_mois.mois AS mois,
GREATEST(p_calendrier_mois.date_debut, p_contrats.date_debut) AS date_debut,
LEAST(p_calendrier_mois.date_fin, p_contrats.date_fin) AS date_fin,
(max(ARRAY[EXTRACT(EPOCH FROM w_profils.date_fin), w_profils.profil_id]))[2] AS profil_id,
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,
avg(etp_theorique) AS equivalent_temps_plein, -- CASE WHEN (max(ARRAY[EXTRACT(EPOCH FROM w_profils.date_fin), w_profils.categorie_conge_code_original]))[2] = 'N' THEN 144 ELSE 151.67 END * AS equivalent_temps_plein,
base.cti_age(LEAST(p_calendrier_mois.date_fin, p_contrats.date_fin), COALESCE(p_salaries.date_naissance, '1962-04-18'::date), 'ny') AS age_id,
LEAST(p_calendrier_mois.date_fin, p_contrats.date_fin)::date - COALESCE(p_salaries.date_naissance, '1962-04-18'::date) AS age_jours,
'0' AS est_hors_periode,
CASE WHEN p_contrats.date_fin >= p_calendrier_mois.date_fin THEN 1 ELSE 0 END AS present_fin_mois,
base.cti_age(date_trunc('month',p_calendrier_mois.date_fin::date)::date, date_trunc('month',to_date(p_salaries.date_entree_ets,'YYYYMMDD'))::date, 'nm') AS anciennete_mois,
floor(base.cti_age(date_trunc('month',p_calendrier_mois.date_fin::date)::date, date_trunc('month',to_date(p_salaries.date_entree_ets,'YYYYMMDD'))::date, 'ny')) AS anciennete_annee_id,
base.cti_age(date_trunc('month',p_calendrier_mois.date_fin::date)::date, date_trunc('month',to_date(p_salaries.date_entree_fp,'YYYYMMDD'))::date, 'nm') AS anciennete_fp_mois,
floor(base.cti_age(date_trunc('month',p_calendrier_mois.date_fin::date)::date, date_trunc('month',to_date(p_salaries.date_entree_fp,'YYYYMMDD'))::date, 'ny')) AS anciennete_fp_annee_id,
base.cti_age(date_trunc('month',p_calendrier_mois.date_fin::date)::date, date_trunc('month',to_date(p_salaries.date_entree_fph,'YYYYMMDD'))::date, 'nm') AS anciennete_fph_mois,
floor(base.cti_age(date_trunc('month',p_calendrier_mois.date_fin::date)::date, date_trunc('month',to_date(p_salaries.date_entree_fph,'YYYYMMDD'))::date, 'ny')) AS anciennete_fph_annee_id
FROM rh.p_contrats
JOIN rh.p_salaries ON p_contrats.salarie_id = p_salaries.oid
JOIN rh.t_etablissements ON p_contrats.etablissement_id = t_etablissements.oid
JOIN rh.t_entreprises ON t_etablissements.entreprise_id = t_entreprises.oid
JOIN base.p_calendrier_mois ON (p_contrats.date_debut <= p_calendrier_mois.date_fin AND p_contrats.date_fin >= p_calendrier_mois.date_debut)
JOIN w_profils ON 1=1
AND w_profils.agent = p_salaries.matricule
AND p_contrats.date_fin BETWEEN w_profils.date_debut AND w_profils.date_fin
JOIN prod_shspub.pippub184_agentp AS ag ON ag.acdagt = w_profils.agent
WHERE p_calendrier_mois.date_debut < date(now())
GROUP BY 1,2,3,4,5,7,8,10,11,12,13,14,15,16,17,18,19
;
]]></sqlcmd>
</NODE>
<NODE label="Historique de la paie">
<sqlcmd><![CDATA[
-- Pré-traitement : reconstitution des bulletins de paie
DROP SEQUENCE IF EXISTS w_hp_seq
;
CREATE TEMP SEQUENCE w_hp_seq
;
-- SELECT * FROM w_hp
DROP TABLE IF EXISTS w_hp
;
CREATE TEMP TABLE w_hp AS
(
SELECT
nextval('w_hp_seq') AS oid,
hp.ocdagt AS matricule,
(ommtrt||'01')::date AS date_debut,
((ommtrt||'01')::date + interval '1 month' - interval '1 day')::date AS date_fin,
ommtrt AS mois, -- mois de paie
ommpay, -- mois de la rétroactivité
t_rubriques.oid AS rubrique_id,
ocdrub,
CASE WHEN rbaedi = 1 OR rqtedi = 1
THEN obacal
ELSE 0
END AS base,
CASE WHEN ocdrub < '495'
THEN omtcal
ELSE 0
END * CASE WHEN redipd = 'D' THEN -1 ELSE 1 END AS montant_brut,
CASE
WHEN rpscot = 'S' AND rtxedi = 1 THEN onucal
WHEN rpscot = '' AND rqtedi = 1 THEN opucal
ELSE 0
END AS taux_salarial,
CASE WHEN rpscot = 'S' -- AND rtxedi = 1 -- AND redipd = 'D'
THEN omtcal
ELSE 0
END * CASE WHEN redipd = 'P' THEN 0 ELSE 1 END AS montant_salarial,
CASE WHEN rpscot = 'P' AND rtxedi = 1
THEN onucal
ELSE 0
END AS taux_patronal,
CASE WHEN rpscot = 'P' AND rtxedi = 1 -- AND redipd = 'D'
THEN omtcal
ELSE 0
END AS montant_patronal,
CASE WHEN ocdrub = '700'
THEN omtref
ELSE 0
END AS net_imposable,
CASE WHEN ocdrub = '990'
THEN omtref
ELSE 0
END AS net_a_payer,
CASE
WHEN rpscot = 'S' AND rbaedi = 1 AND rtxedi = 0
THEN omtcal
ELSE 0
END AS od_net
FROM prod_shspub.pippub184_histop AS hp
JOIN prod_shspub.pippub184_rbentp AS rb ON rb.rcdrub = hp.ocdrub
JOIN rh.t_rubriques ON t_rubriques.code_original = rb.rcdrub
WHERE 1=1
AND redbul = 1
--AND ocdagt = '100009'
--AND ommtrt = 201112
AND ommtrt >= 200901
AND OCDSBD = (SELECT eta_code FROM w_finess)
AND OCDBUD = (SELECT ent_code FROM w_finess)
)
UNION ALL
( -- Heures payées
SELECT
nextval('w_hp_seq') AS oid,
hp.ocdagt AS matricule,
(ommtrt||'01')::date AS date_debut,
((ommtrt||'01')::date + interval '1 month' - interval '1 day')::date AS date_fin,
ommtrt AS mois,
ommpay,
t_rubriques.oid AS rubrique_id,
ocdrub,
obacal AS base,
0 AS montant_brut,
0 AS taux_salarial,
0 AS montant_salarial,
0 AS taux_patronal,
0 AS montant_patronal,
0 AS net_imposable,
0 AS net_a_payer,
0 AS od_net
FROM prod_shspub.pippub184_histop AS hp
JOIN prod_shspub.pippub184_rbentp AS rb ON rb.rcdrub = hp.ocdrub
JOIN rh.t_rubriques ON t_rubriques.code_original = rb.rcdrub
WHERE 1=1
AND redbul = 0
AND ocdrub = '005'
--AND ocdagt = '100009'
--AND ommtrt = 201112
AND ommtrt >= 200901
AND OCDSBD = (SELECT eta_code FROM w_finess)
AND OCDBUD = (SELECT ent_code FROM w_finess)
)
UNION ALL
( -- Effectif payé
SELECT
nextval('w_hp_seq') AS oid,
hp.ocdagt AS matricule,
(ommtrt||'01')::date AS date_debut,
((ommtrt||'01')::date + interval '1 month' - interval '1 day')::date AS date_fin,
ommtrt AS mois,
ommpay,
t_rubriques.oid AS rubrique_id,
ocdrub,
obacal AS base,
0 AS montant_brut,
0 AS taux_salarial,
0 AS montant_salarial,
0 AS taux_patronal,
0 AS montant_patronal,
0 AS net_imposable,
0 AS net_a_payer,
0 AS od_net
FROM prod_shspub.pippub184_histop AS hp
JOIN prod_shspub.pippub184_rbentp AS rb ON rb.rcdrub = hp.ocdrub
JOIN rh.t_rubriques ON t_rubriques.code_original = rb.rcdrub
WHERE 1=1
AND redbul = 0
AND ocdrub = 'EFF1'
--AND ocdagt = '100009'
--AND ommtrt = 201112
AND ommtrt >= 200901
AND OCDSBD = (SELECT eta_code FROM w_finess)
AND OCDBUD = (SELECT ent_code FROM w_finess)
)
;
-- Suppression des lignes de paie à zéro (sauf la ligne contenant les heures payées '005','EFF1')
DELETE FROM w_hp
WHERE 1=1
--AND base = 0
AND montant_brut = 0
AND montant_salarial = 0
AND montant_patronal = 0
AND net_imposable = 0
AND net_a_payer = 0
AND od_net = 0
AND ocdrub != '005'
AND ocdrub != 'EFF1'
;
CREATE INDEX i_w_hp_1
ON w_hp
USING btree (matricule)
;
CREATE INDEX i_w_hp_2
ON w_hp
USING btree (date_fin)
;
CREATE INDEX i_w_hp_3
ON w_hp
USING btree (rubrique_id)
;
-- Peuplement de l'historique de la paie
TRUNCATE rh.p_historique_paie
;
-- Activation des index
SELECT base.cti_stash_table_indexes('rh', 'p_historique_paie')
;
INSERT INTO rh.p_historique_paie
(
age_id,
contrat_id,
contrat_mois_id,
organisme_cotisation_id,
profil_id,
rubrique_id,
salarie_id,
date_debut,
date_fin,
date_paie,
mois_activite,
mois_paie,
base,
montant_brut,
taux_cotisation_salarie,
montant_cotisation_salarie,
taux_cotisation_patronale,
montant_cotisation_patronale,
montant_avantage_nature,
montant_frais_imposables,
montant_od_net_salarie,
montant_net_imposable_salarie,
montant_net_a_payer_salarie,
compte_id
)
SELECT
date_part('year', age(w_hp.date_fin, date_naissance)) AS age_id,
coalesce((max(ARRAY[EXTRACT(EPOCH FROM p_contrats.date_fin),p_contrats.oid]))[2], 0) AS contrat_id,
coalesce((max(ARRAY[EXTRACT(EPOCH FROM p_contrats_mois.date_fin),p_contrats_mois.oid]))[2], 0) AS contrat_mois_id,
0 AS organisme_cotisation_id,
coalesce((max(ARRAY[EXTRACT(EPOCH FROM w_profils.date_fin), w_profils.profil_id]))[2], '0') AS profil_id,
w_hp.rubrique_id,
p_salaries.oid AS salarie_id,
(ommpay||'01')::date AS date_debut,
((ommpay||'01')::date + interval '1 month' - interval '1 day')::date AS date_fin,
w_hp.date_fin AS date_paie,
w_hp.ommpay AS mois_activite,
w_hp.mois AS mois_paie,
w_hp.base AS base,
w_hp.montant_brut AS montant_brut,
w_hp.taux_salarial AS taux_cotisation_salarie,
w_hp.montant_salarial AS montant_cotisation_salarie,
w_hp.taux_patronal AS taux_cotisation_patronale,
w_hp.montant_patronal AS montant_cotisation_patronale,
0 AS montant_avantage_nature,
0 AS montant_frais_imposables,
od_net AS montant_od_net_salarie,
w_hp.net_imposable AS montant_net_imposable_salarie,
w_hp.net_a_payer AS montant_net_a_payer_salarie,
0 AS compte_id
FROM w_hp
JOIN rh.p_salaries ON p_salaries.matricule = w_hp.matricule
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.ommpay
LEFT JOIN rh.p_contrats ON p_contrats.oid = p_contrats_mois.contrat_id
LEFT JOIN w_profils ON w_profils.numero_situation = p_contrats.numero_contrat
GROUP BY 1,4,6,7,8,9,10,11,12,13,14,15,16,17,18,19,20,21,22,23,24,
w_hp.oid -- permet d'avoir n lignes d'historique de paie lorsqu'il s'agit de retro-activité
;
-- Re-activation des index
SELECT base.cti_stash_pop_table_indexes('rh', 'p_historique_paie')
;
-- Lorsqu'une paye n'est pas couverte par un contrat un mois donné
-- générer une ventilation de contrat supplémentaire pour ce mois.
-- Par la droite.
INSERT INTO rh.p_contrats_mois(
salarie_id,
contrat_id,
mois_activite,
date_debut,
date_fin,
profil_id,
nombre_debut_contrat,
nombre_fin_contrat,
equivalent_temps_plein,
age_id,
age_jours,
est_hors_periode,
present_fin_mois,
anciennete_mois,
anciennete_annee_id,
anciennete_fp_mois,
anciennete_fp_annee_id,
anciennete_fph_mois,
anciennete_fph_annee_id
)
SELECT
p_historique_paie.salarie_id,
(max(ARRAY[EXTRACT(EPOCH FROM p_contrats_mois.date_fin),p_contrats.oid]))[2] as contrat_id,
p_historique_paie.mois_activite,
p_historique_paie.date_debut,
p_historique_paie.date_fin,
(max(ARRAY[EXTRACT(EPOCH FROM p_contrats_mois.date_fin),p_contrats_mois.profil_id]))[2] as profil_id,
0 AS nombre_debut_contrat,
0 AS nombre_fin_contrat,
0 AS equivalent_temps_plein,
(max(ARRAY[EXTRACT(EPOCH FROM p_contrats_mois.date_fin),p_contrats_mois.age_id]))[2] AS age_id,
(max(ARRAY[EXTRACT(EPOCH FROM p_contrats_mois.date_fin),p_contrats_mois.age_jours]))[2] AS age_jours,
1 AS est_hors_periode,
0 AS present_fin_mois,
(max(ARRAY[EXTRACT(EPOCH FROM p_contrats_mois.date_fin),p_contrats_mois.anciennete_mois]))[2] AS anciennete_mois,
(max(ARRAY[EXTRACT(EPOCH FROM p_contrats_mois.date_fin),p_contrats_mois.anciennete_annee_id]))[2] AS anciennete_annee_id,
(max(ARRAY[EXTRACT(EPOCH FROM p_contrats_mois.date_fin),p_contrats_mois.anciennete_fp_mois]))[2] AS anciennete_fp_mois,
(max(ARRAY[EXTRACT(EPOCH FROM p_contrats_mois.date_fin),p_contrats_mois.anciennete_fp_annee_id]))[2] AS anciennete_fp_annee_id,
(max(ARRAY[EXTRACT(EPOCH FROM p_contrats_mois.date_fin),p_contrats_mois.anciennete_fph_mois]))[2] AS anciennete_fph_mois,
(max(ARRAY[EXTRACT(EPOCH FROM p_contrats_mois.date_fin),p_contrats_mois.anciennete_fph_annee_id]))[2] AS anciennete_fph_annee_id
FROM rh.p_historique_paie
JOIN rh.p_contrats ON p_contrats.salarie_id = p_historique_paie.salarie_id
JOIN rh.p_contrats_mois ON p_contrats_mois.contrat_id = p_contrats.oid
WHERE 1=1
AND
(1!=1
OR p_historique_paie.contrat_mois_id IS NULL
OR p_historique_paie.contrat_mois_id = 0
)
AND p_historique_paie.date_paie > p_contrats_mois.date_fin -- la fin du contrat doit être antérieure au bulletin de paie
GROUP BY 1,3,4,5,7,8,9,12,13
;
-- Associer à l'historique de paie ce nouveau mois ventilé
UPDATE rh.p_historique_paie
SET
contrat_id = p_contrats_mois.contrat_id,
contrat_mois_id = p_contrats_mois.oid,
profil_id = p_contrats_mois.profil_id
FROM rh.p_contrats_mois
WHERE 1=1
AND p_historique_paie.salarie_id = p_contrats_mois.salarie_id
AND p_historique_paie.mois_activite = p_contrats_mois.mois_activite
AND
(1!=1
OR p_historique_paie.contrat_mois_id IS NULL
OR p_historique_paie.contrat_mois_id = 0
)
;
-- Par la gauche.
INSERT INTO rh.p_contrats_mois(
salarie_id,
contrat_id,
mois_activite,
date_debut,
date_fin,
profil_id,
nombre_debut_contrat,
nombre_fin_contrat,
equivalent_temps_plein,
age_id,
age_jours,
est_hors_periode,
present_fin_mois,
anciennete_mois,
anciennete_annee_id,
anciennete_fp_mois,
anciennete_fp_annee_id,
anciennete_fph_mois,
anciennete_fph_annee_id
)
SELECT
p_historique_paie.salarie_id,
(min(ARRAY[EXTRACT(EPOCH FROM p_contrats_mois.date_debut),p_contrats.oid]))[2] as contrat_id,
p_historique_paie.mois_activite,
p_historique_paie.date_debut,
p_historique_paie.date_fin,
(min(ARRAY[EXTRACT(EPOCH FROM p_contrats_mois.date_debut),p_contrats_mois.profil_id]))[2] as profil_id,
0 AS nombre_debut_contrat,
0 AS nombre_fin_contrat,
0 AS equivalent_temps_plein,
(min(ARRAY[EXTRACT(EPOCH FROM p_contrats_mois.date_debut),p_contrats_mois.age_id]))[2] AS age_id,
(min(ARRAY[EXTRACT(EPOCH FROM p_contrats_mois.date_debut),p_contrats_mois.age_jours]))[2] AS age_jours,
1 AS est_hors_periode,
0 AS present_fin_mois,
(min(ARRAY[EXTRACT(EPOCH FROM p_contrats_mois.date_debut),p_contrats_mois.anciennete_mois]))[2] AS anciennete_mois,
(min(ARRAY[EXTRACT(EPOCH FROM p_contrats_mois.date_debut),p_contrats_mois.anciennete_annee_id]))[2] AS anciennete_annee_id,
(min(ARRAY[EXTRACT(EPOCH FROM p_contrats_mois.date_debut),p_contrats_mois.anciennete_fp_mois]))[2] AS anciennete_fp_mois,
(min(ARRAY[EXTRACT(EPOCH FROM p_contrats_mois.date_debut),p_contrats_mois.anciennete_fp_annee_id]))[2] AS anciennete_fp_annee_id,
(min(ARRAY[EXTRACT(EPOCH FROM p_contrats_mois.date_debut),p_contrats_mois.anciennete_fph_mois]))[2] AS anciennete_fph_mois,
(min(ARRAY[EXTRACT(EPOCH FROM p_contrats_mois.date_debut),p_contrats_mois.anciennete_fph_annee_id]))[2] AS anciennete_fph_annee_id
FROM rh.p_historique_paie
JOIN rh.p_contrats ON p_contrats.salarie_id = p_historique_paie.salarie_id
JOIN rh.p_contrats_mois ON p_contrats_mois.contrat_id = p_contrats.oid
WHERE 1=1
AND
(1!=1
OR p_historique_paie.contrat_mois_id IS NULL
OR p_historique_paie.contrat_mois_id = 0
)
AND p_historique_paie.date_paie < p_contrats_mois.date_debut -- le début du contrat doit être postérieur au bulletin de paie
GROUP BY 1,3,4,5,7,8,9,12,13
;
-- Associer à l'historique de paie ce nouveau mois ventilé
UPDATE rh.p_historique_paie
SET
contrat_id = p_contrats_mois.contrat_id,
contrat_mois_id = p_contrats_mois.oid,
profil_id = p_contrats_mois.profil_id
FROM rh.p_contrats_mois
WHERE 1=1
AND p_historique_paie.salarie_id = p_contrats_mois.salarie_id
AND p_historique_paie.mois_activite = p_contrats_mois.mois_activite
AND
(1!=1
OR p_historique_paie.contrat_mois_id IS NULL
OR p_historique_paie.contrat_mois_id = 0
)
;
-- Création d'une table temp qui regroupe tous les totaux à atteindre pour calcul de l'écart
DROP TABLE IF EXISTS w_totaux
;
CREATE TEMP TABLE w_totaux AS
SELECT
OCDBUD AS ent,
OCDSBD AS eta,
ocdagt AS agent,
ommtrt AS mois,
-- sum(case when ocdrub = '005' then omtcal else 0 end) AS heures, -- pas utilisé
sum(case when ocdrub = '499' then omtcal else 0 end) AS brut,
sum(case when ocdrub = '950' then omtcal else 0 end) AS cots,
sum(case when ocdrub = '951' then omtcal else 0 end) AS cotp,
sum(case when ocdrub = '700' then omtcal else 0 end) AS netf,
sum(case when ocdrub = '990' then omtcal else 0 end) AS netp,
0 AS od,
0 AS fi,
0 AS an
FROM prod_shspub.pippub184_histop
WHERE 1=1
AND ommtrt >= 200901
AND OCDSBD = (SELECT eta_code FROM w_finess)
AND OCDBUD = (SELECT ent_code FROM w_finess)
GROUP BY 1,2,3,4
;
-- Inserer pour chaque bulletin une ligne qui va faire le compte avec le total
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,
rubrique_id,
salarie_id,
taux_cotisation_patronale,
taux_cotisation_salarie,
compte_id
)
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,
sum(an - subq.montant_avantage_nature) AS montant_avantage_nature,
sum(brut - subq.montant_brut) AS montant_brut,
sum(cotp - subq.montant_cotisation_patronale) AS montant_cotisation_patronale,
sum(cots - subq.montant_cotisation_salarie) AS montant_cotisation_salarie,
sum(fi - subq.montant_frais_imposables) AS montant_frais_imposables,
sum(netp - subq.montant_net_a_payer_salarie) AS montant_net_a_payer_salarie,
sum(netf - subq.montant_net_imposable_salarie) AS montant_net_imposable_salarie,
sum(od - subq.montant_od_net_salarie) AS montant_od_net_salarie,
subq.organisme_cotisation_id AS organisme_cotisation_id,
subq.profil_id AS profil_id,
(SELECT oid FROM rh.t_rubriques WHERE code = 'C000') AS rubrique_id,
subq.salarie_id AS salarie_id,
0 AS taux_cotisation_patronale,
0 AS taux_cotisation_salarie,
0 AS compte_id
FROM
(
SELECT
max(p_historique_paie.age_id) AS age_id,
(max(ARRAY[p_historique_paie.mois_paie,p_historique_paie.contrat_id]))[2] AS contrat_id,
(max(ARRAY[p_historique_paie.mois_paie,p_historique_paie.contrat_mois_id]))[2] AS contrat_mois_id,
to_date(p_historique_paie.mois_paie, 'YYYYMM') AS date_debut,
(to_date(p_historique_paie.mois_paie, 'YYYYMM') + interval '1 month' - interval '1 day')::date AS date_fin,
p_historique_paie.date_paie,
p_historique_paie.mois_paie AS 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,
sum(montant_frais_imposables) 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,
sum(montant_od_net_salarie) AS montant_od_net_salarie,
0 AS organisme_cotisation_id,
(max(ARRAY[p_historique_paie.mois_paie,p_historique_paie.profil_id]))[2] AS profil_id,
(SELECT oid FROM rh.t_rubriques WHERE code = 'C000'),
p_historique_paie.salarie_id,
0 AS taux_cotisation_patronale,
0 AS taux_cotisation_salarie,
0 AS compte_id
FROM rh.p_historique_paie
JOIN rh.p_salaries ON p_salaries.oid = p_historique_paie.salarie_id
GROUP BY 4,5,6,7,8,9,18,20,21
) as subq
JOIN rh.p_salaries ON p_salaries.oid = subq.salarie_id
JOIN w_totaux ON 1=1
AND w_totaux.agent = p_salaries.matricule
AND w_totaux.mois = subq.mois_paie
WHERE 1!=1
OR an - subq.montant_avantage_nature != 0
OR brut - subq.montant_brut != 0
OR cotp - subq.montant_cotisation_patronale != 0
OR cots - subq.montant_cotisation_salarie != 0
OR fi - subq.montant_frais_imposables != 0
OR netp - subq.montant_net_a_payer_salarie != 0
OR netf - subq.montant_net_imposable_salarie != 0
OR od - subq.montant_od_net_salarie != 0
GROUP BY 1,2,3,4,5,6,7,8,9, 18,19,20,21
;
-- Màj des Comptes
UPDATE rh.p_historique_paie
SET compte_id = t_compte.oid
FROM rh.p_profils, rh.t_rubriques, w_cor, rh.t_compte
WHERE 1=1
AND p_profils.oid = p_historique_paie.profil_id
AND t_rubriques.oid = p_historique_paie.rubrique_id
AND w_cor.rubrique = t_rubriques.code_original
AND w_cor.statut = p_profils.type_contrat_code_original
AND t_compte.code_original = w_cor.compte
;
-- Màj des Comptes : lorsque non renseigné, le compte agent est utilisé
UPDATE rh.p_historique_paie
SET compte_id = p_profils.compte_salarie_id
FROM rh.p_profils
WHERE 1=1
AND p_profils.oid = p_historique_paie.profil_id
AND p_historique_paie.compte_id = 0
;
]]></sqlcmd>
</NODE>
<NODE label="Ventilation des profils">
<sqlcmd><![CDATA[
-- Ventilation des profils simultanés.
DROP TABLE IF EXISTS w_tmp
;
CREATE TEMP TABLE w_tmp AS
SELECT
p_calendrier_mois.mois,
p_salaries.oid AS salarie_id,
rang,
unite_fonctionnelle_code_original AS uf,
w_profil_sav.profil_id AS profil_id,
GREATEST(p_calendrier_mois.date_debut, w_profil_sav.date_debut) AS date_debut,
LEAST(p_calendrier_mois.date_fin, w_profil_sav.date_fin) AS date_fin,
(LEAST(p_calendrier_mois.date_fin, w_profil_sav.date_fin)-GREATEST(p_calendrier_mois.date_debut, w_profil_sav.date_debut)+1)::numeric * pct::numeric AS nb_det,
0::numeric AS nb_tot,
pct::numeric,
0::numeric AS pct_final
FROM w_profil_sav
JOIN base.p_calendrier_mois ON base.cti_overlaps(w_profil_sav.date_debut, w_profil_sav.date_fin, p_calendrier_mois.date_debut, p_calendrier_mois.date_fin)
JOIN rh.p_salaries ON p_salaries.matricule = w_profil_sav.agent
WHERE p_calendrier_mois.mois BETWEEN 197001::numeric AND to_char(now() + interval '1 year', 'YYYYMM')::numeric
;
UPDATE w_tmp
SET nb_tot = subq.nb_tot
FROM
(
select
mois,
salarie_id,
sum(nb_det) as nb_tot
from w_tmp
group by 1,2
) AS subq
WHERE 1=1
AND w_tmp.mois = subq.mois
AND w_tmp.salarie_id = subq.salarie_id
;
UPDATE w_tmp
SET pct_final = nb_det / nb_tot
;
-- Alimentation des profils simultanés.
TRUNCATE rh.p_profil_contrat_mois
;
INSERT INTO rh.p_profil_contrat_mois (
profil_id,
contrat_mois_id,
salarie_id,
ratio,
mois
)
SELECT
w_tmp.profil_id,
p_contrats_mois.oid,
w_tmp.salarie_id,
sum(pct_final),
w_tmp.mois
FROM w_tmp
JOIN rh.p_contrats_mois ON 1=1
AND p_contrats_mois.salarie_id = w_tmp.salarie_id
AND p_contrats_mois.mois_activite = w_tmp.mois
GROUP BY 1,2,3,5
;
]]></sqlcmd>
</NODE>
<NODE label="Traitement des éléments variables">
<sqlcmd><![CDATA[
-- Identification des lignes de bulletin de paie avec éléments variables (uniquement ceux qui ont leur UF qui a changé).
DROP TABLE IF EXISTS w_lb
;
CREATE TEMP TABLE w_lb AS
SELECT
p_historique_paie.contrat_id,
p_historique_paie.contrat_mois_id,
p_historique_paie.mois_activite,
p_historique_paie.date_debut,
p_historique_paie.date_fin,
p_historique_paie.salarie_id,
p_historique_paie.mois_paie,
p_historique_paie.rubrique_id,
w_ev.unite_fonctionnelle_code_original,
w_ev.service_code_original,
w_ev.lettre_budgetaire_code_original
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
JOIN rh.p_profil_contrat_mois ON p_profil_contrat_mois.contrat_mois_id = p_historique_paie.contrat_mois_id
JOIN rh.p_profils ON p_profils.oid = p_profil_contrat_mois.profil_id
JOIN w_ev ON 1=1
AND w_ev.agent = p_salaries.matricule
AND w_ev.mois = p_historique_paie.mois_activite
AND w_ev.rubrique = t_rubriques.code_original
WHERE 1=1
--AND matricule = '101251' -- MUGNIER P.
--AND matricule = '101285' -- TALHOUET MARJORIE
--AND mois_paie = 201206
AND p_profils.unite_fonctionnelle_code_original != w_ev.unite_fonctionnelle_code_original
GROUP BY 1,2,3,4,5,6,7,8,9,10,11
;
-- Générer la table des profils à chercher.
DROP SEQUENCE IF EXISTS w_profil2find_seq
;
CREATE TEMP SEQUENCE w_profil2find_seq
;
DROP TABLE IF EXISTS w_profil2find
;
CREATE TEMP TABLE w_profil2find AS
SELECT
nextval('w_profil2find_seq') AS profil2find_id,
0 AS profil2find_profil_id, -- nouveau profil_id
0 AS profil2find_contrat_mois_id, -- nouveau contrat_mois_id
p_profil_contrat_mois.profil_id AS pcm_profil_id,
p_profil_contrat_mois.contrat_mois_id AS pcm_contrat_mois_id,
p_profil_contrat_mois.ratio AS pcm_ratio,
p_profil_contrat_mois.mois AS pcm_mois,
p_profil_contrat_mois.salarie_id AS pcm_salarie_id,
w_lb.*,
p_profils.categorie_socio_professionnelle_code_original,
p_profils.code_emploi_code_original,
p_profils.grille_code_original,
p_profils.grille_groupe_code_original,
p_profils.groupe_cotisant_code_original,
p_profils.motif_debut_code_original,
p_profils.motif_fin_code_original,
--w_lb.unite_fonctionnelle_code_original,
p_profils.categorie_conge_code_original,
p_profils.compte_salarie_code_original,
--w_lb.service_code_original,
p_profils.commission_paritaire_code_original,
--w_lb.lettre_budgetaire_code_original,
p_profils.statut_code_original,
p_profils.type_contrat_code_original,
p_profils.type_horaire_code_original,
p_profils.type_temps_travail_code_original,
p_profils.cadre_emploi_code_original,
p_profils.filiere_code_original,
p_profils.categorie_statutaire_code_original,
p_profils.unite_fonctionnelle_code_original AS old_unite_fonctionnelle_code_original,
p_profils.service_code_original AS old_service_code_original,
p_profils.lettre_budgetaire_code_original AS old_lettre_budgetaire_code_original
FROM w_lb
JOIN rh.p_profil_contrat_mois ON p_profil_contrat_mois.contrat_mois_id = w_lb.contrat_mois_id
JOIN rh.p_profils ON p_profils.oid = p_profil_contrat_mois.profil_id
;
-- Insérer dans p_profils les nouveaux profils.
SELECT base.cti_stash_table_constraints('rh.p_profils')
;
SELECT base.cti_stash_table_indexes('rh.p_profils')
;
INSERT INTO rh.p_profils
(
categorie_socio_professionnelle_code_original,
code_emploi_code_original,
grille_code_original,
grille_groupe_code_original,
groupe_cotisant_code_original,
motif_debut_code_original,
motif_fin_code_original,
unite_fonctionnelle_code_original,
categorie_conge_code_original,
compte_salarie_code_original,
service_code_original,
commission_paritaire_code_original,
lettre_budgetaire_code_original,
statut_code_original,
type_contrat_code_original,
type_horaire_code_original,
type_temps_travail_code_original,
cadre_emploi_code_original,
filiere_code_original,
categorie_statutaire_code_original
)
SELECT
w_profil2find.categorie_socio_professionnelle_code_original,
w_profil2find.code_emploi_code_original,
w_profil2find.grille_code_original,
w_profil2find.grille_groupe_code_original,
w_profil2find.groupe_cotisant_code_original,
w_profil2find.motif_debut_code_original,
w_profil2find.motif_fin_code_original,
w_profil2find.unite_fonctionnelle_code_original,
w_profil2find.categorie_conge_code_original,
w_profil2find.compte_salarie_code_original,
w_profil2find.service_code_original,
w_profil2find.commission_paritaire_code_original,
w_profil2find.lettre_budgetaire_code_original,
w_profil2find.statut_code_original,
w_profil2find.type_contrat_code_original,
w_profil2find.type_horaire_code_original,
w_profil2find.type_temps_travail_code_original,
w_profil2find.cadre_emploi_code_original,
w_profil2find.filiere_code_original,
w_profil2find.categorie_statutaire_code_original
FROM w_profil2find
LEFT JOIN rh.p_profils ON 1=1
AND p_profils.type_contrat_code_original = w_profil2find.type_contrat_code_original
AND p_profils.type_horaire_code_original = w_profil2find.type_horaire_code_original
AND p_profils.motif_debut_code_original = w_profil2find.motif_debut_code_original
AND p_profils.motif_fin_code_original = w_profil2find.motif_fin_code_original
AND p_profils.unite_fonctionnelle_code_original = w_profil2find.unite_fonctionnelle_code_original
AND p_profils.service_code_original = w_profil2find.service_code_original
AND p_profils.lettre_budgetaire_code_original = w_profil2find.lettre_budgetaire_code_original
AND p_profils.type_temps_travail_code_original = w_profil2find.type_temps_travail_code_original
AND p_profils.categorie_socio_professionnelle_code_original = w_profil2find.categorie_socio_professionnelle_code_original
AND p_profils.statut_code_original = w_profil2find.statut_code_original
AND p_profils.code_emploi_code_original = w_profil2find.code_emploi_code_original
AND p_profils.commission_paritaire_code_original = w_profil2find.commission_paritaire_code_original
AND p_profils.compte_salarie_code_original = w_profil2find.compte_salarie_code_original
AND p_profils.categorie_conge_code_original = w_profil2find.categorie_conge_code_original
AND p_profils.grille_code_original = w_profil2find.grille_code_original
AND p_profils.grille_groupe_code_original = w_profil2find.grille_groupe_code_original
AND p_profils.groupe_cotisant_code_original = w_profil2find.groupe_cotisant_code_original
AND p_profils.cadre_emploi_code_original = w_profil2find.cadre_emploi_code_original
AND p_profils.filiere_code_original = w_profil2find.filiere_code_original
AND p_profils.categorie_statutaire_code_original = w_profil2find.categorie_statutaire_code_original
WHERE 1=1
AND p_profils.type_contrat_code_original IS NULL
GROUP BY 1,2,3,4,5,6,7,8,9,10,11,12,13,14,15,16,17,18,19,20
;
-- màj les oids et textes des profils.
SELECT rh.cti_reorganize_profils()
;
-- Re-activation des contraintes/index.
SELECT base.cti_stash_pop_table_indexes('rh.p_profils')
;
SELECT base.cti_stash_pop_table_constraints('rh.p_profils')
;
-- Màj de l'oid des profils.
UPDATE w_profil2find
SET profil2find_profil_id = p_profils.oid
FROM rh.p_profils
WHERE 1=1
AND p_profils.type_contrat_code_original = w_profil2find.type_contrat_code_original
AND p_profils.type_horaire_code_original = w_profil2find.type_horaire_code_original
AND p_profils.motif_debut_code_original = w_profil2find.motif_debut_code_original
AND p_profils.motif_fin_code_original = w_profil2find.motif_fin_code_original
AND p_profils.unite_fonctionnelle_code_original = w_profil2find.unite_fonctionnelle_code_original
AND p_profils.service_code_original = w_profil2find.service_code_original
AND p_profils.lettre_budgetaire_code_original = w_profil2find.lettre_budgetaire_code_original
AND p_profils.type_temps_travail_code_original = w_profil2find.type_temps_travail_code_original
AND p_profils.categorie_socio_professionnelle_code_original = w_profil2find.categorie_socio_professionnelle_code_original
AND p_profils.statut_code_original = w_profil2find.statut_code_original
AND p_profils.code_emploi_code_original = w_profil2find.code_emploi_code_original
AND p_profils.commission_paritaire_code_original = w_profil2find.commission_paritaire_code_original
AND p_profils.compte_salarie_code_original = w_profil2find.compte_salarie_code_original
AND p_profils.categorie_conge_code_original = w_profil2find.categorie_conge_code_original
AND p_profils.grille_code_original = w_profil2find.grille_code_original
AND p_profils.grille_groupe_code_original = w_profil2find.grille_groupe_code_original
AND p_profils.groupe_cotisant_code_original = w_profil2find.groupe_cotisant_code_original
AND p_profils.cadre_emploi_code_original = w_profil2find.cadre_emploi_code_original
AND p_profils.filiere_code_original = w_profil2find.filiere_code_original
AND p_profils.categorie_statutaire_code_original = w_profil2find.categorie_statutaire_code_original
;
-- Requete qui "copie" les contrats_mois pour en faire des fictifs.
DROP TABLE IF EXISTS w_p_contrats_mois
;
CREATE TEMP TABLE w_p_contrats_mois AS
SELECT
base.cti_array_accum(w_profil2find.profil2find_id) AS profil2find_id,
nextval('rh.s_contrats_mois') AS oid,
w_profil2find.salarie_id,
w_profil2find.contrat_id,
w_profil2find.mois_activite,
w_profil2find.date_debut,
w_profil2find.date_fin,
max(w_profil2find.profil2find_profil_id) AS profil_id,
p_contrats_mois.nombre_debut_contrat,
p_contrats_mois.nombre_fin_contrat,
p_contrats_mois.equivalent_temps_plein,
p_contrats_mois.age_id,
p_contrats_mois.age_jours,
p_contrats_mois.est_hors_periode,
p_contrats_mois.present_fin_mois,
p_contrats_mois.anciennete_mois,
p_contrats_mois.anciennete_annee_id,
p_contrats_mois.anciennete_fp_mois,
p_contrats_mois.anciennete_fp_annee_id,
p_contrats_mois.anciennete_fph_mois,
p_contrats_mois.anciennete_fph_annee_id,
1 AS fictif,
w_profil2find.pcm_contrat_mois_id AS old_contrat_mois_id
FROM w_profil2find
JOIN rh.p_contrats_mois ON p_contrats_mois.oid = w_profil2find.contrat_mois_id
GROUP BY 3,4,5,6,7,9,10,11,12,13,14,15,16,17,18,19,20,21,22,23
;
INSERT INTO rh.p_contrats_mois(
oid,
salarie_id,
contrat_id,
mois_activite,
date_debut,
date_fin,
profil_id,
nombre_debut_contrat,
nombre_fin_contrat,
equivalent_temps_plein,
age_id,
age_jours,
est_hors_periode,
present_fin_mois,
anciennete_mois,
anciennete_annee_id,
anciennete_fp_mois,
anciennete_fp_annee_id,
anciennete_fph_mois,
anciennete_fph_annee_id,
fictif
)
SELECT
oid,
salarie_id,
contrat_id,
mois_activite,
date_debut,
date_fin,
profil_id,
nombre_debut_contrat,
nombre_fin_contrat,
equivalent_temps_plein,
age_id,
age_jours,
est_hors_periode,
present_fin_mois,
anciennete_mois,
anciennete_annee_id,
anciennete_fp_mois,
anciennete_fp_annee_id,
anciennete_fph_mois,
anciennete_fph_annee_id,
fictif
FROM w_p_contrats_mois
;
-- Màj des id des contrats mois dans profil2find.
UPDATE w_profil2find
SET profil2find_contrat_mois_id = w_p_contrats_mois.oid
FROM w_p_contrats_mois
WHERE w_profil2find.profil2find_id = ANY (w_p_contrats_mois.profil2find_id)
;
INSERT INTO rh.p_profil_contrat_mois (
profil_id,
contrat_mois_id,
salarie_id,
ratio,
mois
)
SELECT subq.*
FROM
(
SELECT
profil2find_profil_id AS profil_id,
profil2find_contrat_mois_id AS contrat_mois_id,
salarie_id,
sum(pcm_ratio),
pcm_mois
FROM w_profil2find
GROUP BY 1,2,3,5,mois_paie,rubrique_id
) AS subq
GROUP BY 1,2,3,4,5
;
-- Associer les lignes d'historique de paie aux contrats mois
UPDATE rh.p_historique_paie
SET contrat_mois_id = w_profil2find.profil2find_contrat_mois_id
FROM w_profil2find
WHERE 1=1
AND w_profil2find.salarie_id = p_historique_paie.salarie_id
AND w_profil2find.mois_paie = p_historique_paie.mois_paie
AND w_profil2find.rubrique_id = p_historique_paie.rubrique_id
AND w_profil2find.mois_activite = p_historique_paie.mois_activite
AND w_profil2find.contrat_mois_id = p_historique_paie.contrat_mois_id
;
]]></sqlcmd>
</NODE>
<NODE label="Arrêts de travail">
<sqlcmd><![CDATA[
-- Récupération des absences.
TRUNCATE rh.p_arrets_travail
;
ALTER SEQUENCE rh.s_arrets_travail RESTART WITH 1
;
INSERT INTO rh.p_arrets_travail(
salarie_id,
contrat_id,
mois_activite,
date_debut,
date_fin,
date_reprise,
motif_arret_id,
precision_motif_arret_id,
nb_jours
)
SELECT
p_salaries.oid,
p_contrats.oid AS contrat_id,
substr(absenp.bdtdab, 1, 6)::numeric AS mois_activite,
to_date(absenp.bdtdab, 'YYYYMMDD') AS date_debut,
to_date(absenp.bdtfab, 'YYYYMMDD') AS date_fin,
to_date(absenp.bdtfab, 'YYYYMMDD') + interval '1 day' AS date_reprise, -- date de reprise TOUJOURS égal à date de fin + 1 jour
t_motifs_arret.oid AS motif_arret_id,
0 AS precision_motif_arret_id,
absenp.bdusjo AS nb_jours
FROM prod_shspub.pippub184_absenp AS absenp
JOIN rh.p_salaries ON p_salaries.matricule = absenp.bcdagt
JOIN rh.p_contrats ON 1=1
AND p_contrats.salarie_id = p_salaries.oid
AND to_date(absenp.bdtfab, 'YYYYMMDD') BETWEEN p_contrats.date_debut AND p_contrats.date_fin
LEFT JOIN rh.t_motifs_arret ON t_motifs_arret.code_original = absenp.bcdmot
WHERE 1=1
AND absenp.bcdsbd = (SELECT eta_code FROM w_finess)
AND absenp.bcdbud = (SELECT ent_code FROM w_finess)
;
-- Ventilation mensuelle (date de début => date de reprise).
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
)
SELECT
p_arrets_travail.oid AS arret_travail_id,
p_arrets_travail.salarie_id AS salarie_id,
(max(ARRAY[EXTRACT(EPOCH FROM p_contrats_mois.date_debut), p_contrats_mois.contrat_id]))[2] AS contrat_id,
(max(ARRAY[EXTRACT(EPOCH FROM p_contrats_mois.date_debut), p_contrats_mois.oid]))[2] AS contrat_mois_id,
p_calendrier_mois.mois AS mois_activite,
CASE WHEN p_arrets_travail.date_debut BETWEEN p_calendrier_mois.date_debut AND p_calendrier_mois.date_fin THEN 1 ELSE 0 END AS nombre_debut_arret,
CASE WHEN p_arrets_travail.date_fin BETWEEN p_calendrier_mois.date_debut AND p_calendrier_mois.date_fin THEN 1 ELSE 0 END AS nombre_fin_arret,
CASE WHEN p_arrets_travail.date_reprise BETWEEN p_calendrier_mois.date_debut AND p_calendrier_mois.date_fin THEN 1 ELSE 0 END AS nombre_reprise_apres_arret,
GREATEST(p_calendrier_mois.date_debut, p_arrets_travail.date_debut) AS date_debut,
LEAST(p_calendrier_mois.date_fin, p_arrets_travail.date_fin) AS date_fin,
0 AS nb_jours
FROM base.p_calendrier_mois
JOIN rh.p_arrets_travail ON base.cti_overlaps(p_arrets_travail.date_debut, p_arrets_travail.date_reprise, p_calendrier_mois.date_debut, p_calendrier_mois.date_fin)
LEFT JOIN rh.p_contrats_mois ON 1=1
AND p_contrats_mois.salarie_id = p_arrets_travail.salarie_id
AND base.cti_overlaps(p_contrats_mois.date_debut, p_contrats_mois.date_fin, p_calendrier_mois.date_debut, p_calendrier_mois.date_fin)
--WHERE p_arrets_travail.salarie_id = 9151
GROUP BY 1,2,5,6,7,8,9,10,11
--ORDER BY 9 desc, 5 desc
;
-- DOIT TOUJOURS TRAITER 0 enregistrement : Suppression des mois sans évènements séparant la date de fin et la date de reprise.
/*
DELETE FROM rh.p_arrets_travail_mois
WHERE 1=1
AND nb_debut_arret = 0
AND nb_fin_arret = 0
AND nb_reprise_apres_arret = 0
AND date_fin < date_debut
;
*/
-- Màj des dates de début/fin pour les reprises isolées sur un mois.
UPDATE rh.p_arrets_travail_mois
SET
date_debut = p_arrets_travail.date_reprise,
date_fin = p_arrets_travail.date_reprise
FROM rh.p_arrets_travail
WHERE 1=1
AND p_arrets_travail.oid = p_arrets_travail_mois.arret_travail_id
AND nb_debut_arret = 0
AND nb_fin_arret = 0
AND nb_reprise_apres_arret = 1
;
-- Calcul de la durée de l'absence "nb_jours".
UPDATE rh.p_arrets_travail_mois
SET nb_jours = date_fin - date_debut + 1
;
-- Lorsque reprise isolée sur un mois, durée à 0.
UPDATE rh.p_arrets_travail_mois
SET nb_jours = 0
WHERE 1=1
AND nb_debut_arret = 0
AND nb_fin_arret = 0
AND nb_reprise_apres_arret = 1
;
-- Quand absences contigües, ne pas compter comme une reprise (date reprise absence N = date début absence N+1).
UPDATE rh.p_arrets_travail_mois
SET nb_reprise_apres_arret = 0
FROM rh.p_arrets_travail AS a1, rh.p_arrets_travail AS a2
WHERE 1=1
AND arret_travail_id = a1.oid
AND a1.salarie_id = a2.salarie_id
AND a1.date_reprise = a2.date_debut
AND nb_reprise_apres_arret = 1
;
-- Quand reprise idolée sur un mois et sans contrat, la supprimer.
DELETE FROM rh.p_arrets_travail_mois
WHERE p_arrets_travail_mois.contrat_id IS NULL
;
]]></sqlcmd>
</NODE>
<NODE label="Visites Médicales">
<sqlcmd><![CDATA[
]]></sqlcmd>
</NODE>
<NODE label="Accidents du travail">
<sqlcmd><![CDATA[
-- Peuplement de rh.p_accident_travail
-- (basé sur les absences de type "AT" auxquels on ajoute la cause et la conséquence).
TRUNCATE rh.p_accident_travail
;
ALTER SEQUENCE rh.s_accident_travail RESTART WITH 1
;
INSERT INTO rh.p_accident_travail(
salarie_id,
contrat_id,
contrat_mois_id,
mois_activite,
date,
accident_circonstance_id,
accident_lieu_id,
accident_nature_id,
accident_siege_id
)
SELECT
p_salaries.oid,
p_contrats.oid AS contrat_id,
p_contrats_mois.oid AS contrat_mois_id,
substr(absenp.bdtab1, 1, 6)::numeric AS mois_activite,
to_date(absenp.bdtab1, 'YYYYMMDD') AS date,
coalesce(t_accident_circonstance.oid, 0) AS accident_circonstance_id, -- Causes
coalesce(t_accident_lieu.oid, 0) AS accident_lieu_id, -- Conséquences
0,
0
FROM prod_shspub.pippub184_absenp AS absenp
JOIN rh.p_salaries ON p_salaries.matricule = absenp.bcdagt
LEFT JOIN rh.t_accident_circonstance ON t_accident_circonstance.code_original = absenp.bcoinf
LEFT JOIN rh.t_accident_lieu ON t_accident_lieu.code_original = absenp.bsuinf
JOIN rh.p_contrats ON 1=1
AND p_contrats.salarie_id = p_salaries.oid
AND to_date(absenp.bdtab1, 'YYYYMMDD') BETWEEN p_contrats.date_debut AND p_contrats.date_fin
JOIN rh.p_contrats_mois ON 1=1
AND p_contrats_mois.contrat_id = p_contrats.oid
AND to_date(absenp.bdtab1, 'YYYYMMDD') BETWEEN p_contrats_mois.date_debut AND p_contrats_mois.date_fin
WHERE 1=1
AND absenp.bcdsbd = (SELECT eta_code FROM w_finess)
AND absenp.bcdbud = (SELECT ent_code FROM w_finess)
AND absenp.bcdmot = 'AT'
GROUP BY 1,2,3,4,5,6,7,8
;
]]></sqlcmd>
</NODE>
<NODE label="Formations">
<sqlcmd><![CDATA[
]]></sqlcmd>
</NODE>
<NODE label="Handicap">
<sqlcmd><![CDATA[
]]></sqlcmd>
</NODE>
</NODE>
<NODE name="POST" label="POST-TRAITEMENTS" >
<NODE label="Adaptation ETP Théorique 30">
<sqlcmd><![CDATA[
-- Pas de temps plein si contrats fictif
UPDATE rh.p_contrats_mois
SET equivalent_temps_plein = 0
WHERE fictif = '1' AND equivalent_temps_plein <> 0 ;
-- Ventilation au 30eme sur le même mois
-- DROP TABLE IF EXISTS w_contrats_multiples;
-- CREATE TEMP TABLE w_contrats_multiples AS
-- SELECT salarie_id,
-- mois_activite,
-- count(*) AS nb,
-- SUM(date_fin - date_debut + 1) AS nb_jours,
-- (MAX(Array[date_fin::text,p_contrats_mois.oid::text]))[2]::bigint AS contrat_mois_last_id,
-- (MAX(Array[date_fin::text,(date_fin - date_debut + 1)::text]))[2]::bigint AS nb_jours_last
-- FROM rh.p_contrats_mois
-- WHERE fictif IS DISTINCT FROM '1'
-- GROUP BY 1,2
-- HAVING SUM(CASE WHEN fictif <> 1 THEN 1 ELSE 0 END) > 1;
-- UPDATE w_contrats_multiples
-- SET nb_jours_last = 30 - nb_jours + nb_jours_last;
-- UPDATE rh.p_contrats_mois
-- SET equivalent_temps_plein = CASE WHEN oid <> contrat_mois_last_id THEN equivalent_temps_plein / 30 * (date_fin - date_debut + 1) ELSE equivalent_temps_plein / 30 * nb_jours_last END
-- FROM w_contrats_multiples
-- WHERE w_contrats_multiples.salarie_id = p_contrats_mois.salarie_id AND
-- w_contrats_multiples.mois_activite = p_contrats_mois.mois_activite AND
-- fictif IS DISTINCT FROM '1' ;
-- Adaptation etp à duree dansle mois
DROP TABLE IF EXISTS w_contrats_mois_partiels;
CREATE TEMP TABLE w_contrats_mois_partiels AS
SELECT salarie_id,
mois_activite,
SUM(p_contrats_mois.date_fin - p_contrats_mois.date_debut + 1) AS nb_jours,
MAX(p_calendrier_mois.date_fin - p_calendrier_mois.date_debut + 1) AS nb_jours_mois
FROM rh.p_contrats_mois
JOIN base.p_calendrier_mois ON mois_activite = p_calendrier_mois.mois
WHERE fictif IS DISTINCT FROM '1'
GROUP BY 1,2;
UPDATE rh.p_contrats_mois
SET equivalent_temps_plein =
equivalent_temps_plein *
(p_contrats_mois.date_fin - p_contrats_mois.date_debut + 1.00) /
CASE WHEN nb_jours <> nb_jours_mois THEN 30 ELSE nb_jours_mois END
FROM base.p_calendrier_mois,
w_contrats_mois_partiels
WHERE
p_contrats_mois.salarie_id = w_contrats_mois_partiels.salarie_id AND
p_contrats_mois.mois_activite = w_contrats_mois_partiels.mois_activite AND
p_contrats_mois.mois_activite = p_calendrier_mois.mois AND
fictif <> 1 AND
(
p_contrats_mois.date_debut > p_calendrier_mois.date_debut OR
p_contrats_mois.date_fin < p_calendrier_mois.date_fin
);
-- Pas d'etp sur sortis
DROP TABLE IF EXISTS w_contrats_mois_sortis;
CREATE TEMP TABLE w_contrats_mois_sortis AS
SELECT salarie_id,
p_contrats_mois.oid AS contrat_mois_id,
mois_activite,
p_contrats_mois.date_debut,
p_contrats_mois.date_fin
FROM rh.p_contrats_mois
JOIN rh.p_salaries ON salarie_id = p_salaries.oid
LEFT JOIN prod_shspub.pippub184_agpayp ON matricule = ACDAGT AND
(
p_contrats_mois.date_debut BETWEEN DATE(adtpay) AND date(ADTFPA) AND ASSPAY <> 3 AND ASSPAY <> 9 OR
p_contrats_mois.date_fin BETWEEN DATE(adtpay) AND date(ADTFPA) AND ASSPAY <> 3 AND ASSPAY <> 9
)
WHERE fictif IS DISTINCT FROM '1' AND ACDAGT IS NULL AND
equivalent_temps_plein <> 0;
UPDATE rh.p_contrats_mois
SET equivalent_temps_plein = 0
FROM w_contrats_mois_sortis
WHERE w_contrats_mois_sortis.contrat_mois_id = p_contrats_mois.oid ;
-- Initialisation de l'ETP ventilé mensuellement à 0 lorsque qu'aucune rubrique d'heures payées
-- n'est présente sur le bulletin de paie du mois.
UPDATE rh.p_contrats_mois
SET equivalent_temps_plein = 0
WHERE 1=1
AND equivalent_temps_plein <> 0
AND oid NOT IN
(
SELECT contrat_mois_id
FROM rh.p_historique_paie
WHERE rubrique_id IN (SELECT oid FROM rh.t_rubriques WHERE code_calcul = '1')
)
;
-- Report des ratios sur des sorties vers des non sorties
DROP TABLE IF EXISTS w_profils_contrats_mois_absents;
CREATE TEMP TABLE w_profils_contrats_mois_absents AS
SELECT p_contrats_mois.oid AS contrat_mois_id,
mois_activite, matricule,
MIN(CASE WHEN groupe_cotisant_code NOT IN ('3', '9') THEN p_profil_contrat_mois.profil_id ELSE NULL END) AS profil_id_1,
SUM(CASE WHEN groupe_cotisant_code NOT IN ('3', '9') THEN 1 ELSE 0 END) AS nb_1,
SUM(CASE WHEN groupe_cotisant_code IN ('3', '9') THEN 1 ELSE 0 END) AS nb_9,
SUM(CASE WHEN groupe_cotisant_code NOT IN ('3', '9') THEN ratio ELSE 0 END) AS ratio_1,
SUM(CASE WHEN groupe_cotisant_code IN ('3', '9') THEN ratio ELSE 0 END) AS ratio_9
FROM rh.p_contrats_mois
JOIN rh.p_salaries on salarie_id = p_salaries.oid
JOIN rh.p_profil_contrat_mois ON p_profil_contrat_mois.contrat_mois_id = p_contrats_mois.oid
JOIN rh.p_profils ON p_profil_contrat_mois.profil_id = p_profils.oid
GROUP BY 1,2,3
HAVING count(*) > 1 AND
SUM(CASE WHEN groupe_cotisant_code IN ('3', '9') THEN 1 ELSE 0 END) <> 0 AND
SUM(CASE WHEN groupe_cotisant_code NOT IN ('3', '9') THEN 1 ELSE 0 END) <> 0;
UPDATE rh.p_profil_contrat_mois
SET ratio =
CASE WHEN groupe_cotisant_code IN ('3', '9') THEN 0
WHEN profil_id = profil_id_1 THEN ratio + ratio_9
ELSE ratio END
FROM rh.p_profils,
w_profils_contrats_mois_absents
WHERE p_profil_contrat_mois.profil_id = p_profils.oid AND
p_profil_contrat_mois.contrat_mois_id = w_profils_contrats_mois_absents.contrat_mois_id;
]]></sqlcmd>
</NODE>
<NODE label="Recherche comptes dans MANDAP"
members="0901,0902,0903,0904,0905,0906,0907,0908,0909,0910,0911,0912
,1001,1002,1003,1004,1005,1006,1007,1008,1009,1010,1011,1012
,1101,1102,1103,1104,1105,1106,1107,1108,1109,1110,1111,1112
,1201,1202,1203,1204,1205,1206,1207,1208,1209,1210,1211,1212
,1301,1302,1303,1304,1305,1306,1307,1308,1309,1310,1311,1312">
<sqlcmd><![CDATA[
DROP TABLE IF EXISTS w_MANDAP;
CREATE TEMP TABLE w_MANDAP AS
SELECT p_salaries.oid AS salarie_id, 20#MEMBER# AS MMMTRT, MMMPAY, t_rubriques.oid AS rubrique_id, MIN(t_compte.oid) AS compte_id
FROM prod_shspub.pippub184h_mandap#MEMBER#
JOIN rh.p_salaries ON MCDAGT = p_salaries.matricule
JOIN rh.t_compte ON MCDCHA = t_compte.code
JOIN rh.t_rubriques ON MCDRUB = t_rubriques.code
GROUP BY 1,2,3,4
HAVING count(DISTINCT MCDCHA) = 1;
UPDATE rh.p_historique_paie
SET compte_id = w_MANDAP.compte_id
FROM w_MANDAP
WHERE p_historique_paie.salarie_id = w_MANDAP.salarie_id AND
p_historique_paie.mois_paie = w_MANDAP.MMMTRT AND
p_historique_paie.mois_activite = w_MANDAP.MMMPAY AND
p_historique_paie.rubrique_id = w_MANDAP.rubrique_id AND
mois_paie = MMMTRT AND
p_historique_paie.compte_id <> w_MANDAP.compte_id;
]]></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 label="Nettoyage COMPLET des tables (spécial public)">
<sqlcmd><![CDATA[
-- uniquement dans le public (table livrée dans le privé)
TRUNCATE rh.t_categories_socio_professionnelle;
]]></sqlcmd>
</NODE>
</NODE>
</ROOT>