<?xml version="1.0" encoding="ISO-8859-1"?>
|
|
<ROOT>
|
|
<NODE name="INIT" type="common" />
|
|
<NODE name="PROD" label="Synchronisation données">
|
|
<NODE label="Listing des salariés CTI">
|
|
<sqlcmd><![CDATA[
|
|
|
|
-- Recensement des salariés CTI
|
|
DROP TABLE IF EXISTS w_sal_pla
|
|
;
|
|
|
|
CREATE TEMP TABLE w_sal_pla AS
|
|
SELECT
|
|
p_salaries.oid AS salarie_id,
|
|
p_salaries.matricule
|
|
FROM rh.p_salaries
|
|
;
|
|
|
|
-- Création d'index.
|
|
CREATE INDEX w_sal_pla_i_matricule ON w_sal_pla USING btree (matricule)
|
|
;
|
|
|
|
]]></sqlcmd>
|
|
</NODE>
|
|
<NODE label="Récupération des salariés GEOCOM">
|
|
<sqlcmd><![CDATA[
|
|
DROP TABLE IF EXISTS w_salaries
|
|
;
|
|
|
|
CREATE TEMP TABLE w_salaries AS
|
|
SELECT
|
|
idpers, -- ID GEOCOM
|
|
lpad(persnr, 6, 0) AS matricule,
|
|
w_sal_pla.salarie_id -- ID CTI
|
|
FROM prod_geocom.personal
|
|
JOIN w_sal_pla ON w_sal_pla.matricule = lpad(persnr, 6, 0) -- Pour récupérer salarie_id de CTI
|
|
;
|
|
|
|
]]></sqlcmd>
|
|
</NODE>
|
|
<NODE label="Gestion des entreprises/établissements">
|
|
<sqlcmd><![CDATA[
|
|
|
|
-- Création d'une table Entreprise/Etablissement.
|
|
DROP TABLE IF EXISTS w_entets
|
|
;
|
|
|
|
CREATE TEMP TABLE w_entets AS
|
|
select
|
|
max(ent.oid) as entreprise_id,
|
|
max(ets.oid) as etablissement_id,
|
|
ent.planning_code||ets.planning_code as entets_code
|
|
from rh.t_entreprises as ent
|
|
join rh.t_etablissements as ets on ets.entreprise_id = ent.oid
|
|
Where 1=1
|
|
and ent.oid != 0
|
|
and ets.oid != 0
|
|
GROUP BY ent.planning_code||ets.planning_code
|
|
;
|
|
|
|
]]></sqlcmd>
|
|
</NODE>
|
|
<NODE label="Gestion des données journalières du planning">
|
|
<sqlcmd><![CDATA[
|
|
|
|
DROP SEQUENCE IF EXISTS w_planning_seq
|
|
;
|
|
|
|
CREATE TEMP SEQUENCE w_planning_seq
|
|
;
|
|
|
|
DROP TABLE IF EXISTS w_planning
|
|
;
|
|
|
|
-- Table temporaire de récupération des données du planning
|
|
DROP TABLE IF EXISTS w_planning
|
|
;
|
|
|
|
CREATE TEMP TABLE w_planning AS
|
|
SELECT
|
|
nextval('w_planning_seq') as cptres1_id,
|
|
w_salaries.salarie_id AS salarie_id, --ID Salarié CTI
|
|
w_salaries.idpers, -- ID Salarié GEOCOM
|
|
w_salaries.matricule AS matricule,
|
|
null::bigint AS contrat_id,
|
|
null::bigint AS contrat_mois_id,
|
|
dplan.day,
|
|
date(dplan.day) AS date,
|
|
to_char(dplan.day, 'IYYYIW'::text)::numeric AS semaine,
|
|
to_char(dplan.day, 'YYYYMM'::text)::numeric AS mois,
|
|
''::text AS etablissement_code,
|
|
null::bigint AS etablissement_id,
|
|
''::text AS qualification_code,
|
|
dplanabr.typeabr AS type_evenement,
|
|
dplanabr.abr AS horaire_code,
|
|
''::text AS service_code,
|
|
''::text AS niveau_code, -- Pas de notion de niveau pour l'instant
|
|
CASE
|
|
WHEN dplanabr.typeabr = 2 -- Type absence
|
|
THEN dplanabr.abr
|
|
ELSE NULL
|
|
END AS absence_code,
|
|
dplan.normhrs AS temps_prevu_geocom,
|
|
dplan.hours AS temps_travail_geocom,
|
|
dplan.hoursabw AS temps_absence_geocom,
|
|
0 AS temps_du_initial,
|
|
0 AS temps_du,
|
|
0 AS temps_du_ajuste,
|
|
0 AS temps_valide,
|
|
0 AS temps_valide_ajuste,
|
|
0 AS temps_absence,
|
|
0 AS temps_absence_ajuste
|
|
FROM w_salaries
|
|
JOIN prod_geocom.dplan ON dplan.idpers = w_salaries.idpers
|
|
JOIN prod_geocom.dplanabr ON dplanabr.idpers = dplan.idpers AND dplanabr.day = dplan.day -- Attachement de l'abbraviation (code travail/absence)
|
|
WHERE
|
|
dplanabr.typeabr IN (1,2) AND -- 1: Type travail, 2: Type absence, 3: Semble être type astreinte
|
|
(dplanabr.typeabr = 1 AND dplan.hours != 0 OR dplanabr.typeabr = 2 AND dplan.hoursabw != 0)
|
|
ORDER BY dplan.day
|
|
;
|
|
|
|
-- Gestion spécifique de l'attribution des différents temps
|
|
UPDATE w_planning
|
|
SET
|
|
temps_du_initial = CASE WHEN type_evenement = 1 THEN temps_prevu_geocom ELSE 0 END, -- Temps travail
|
|
temps_du = CASE WHEN type_evenement = 1 THEN temps_travail_geocom ELSE 0 END, -- Temps travail
|
|
temps_du_ajuste = CASE WHEN type_evenement = 1 THEN temps_travail_geocom ELSE 0 END, -- Temps travail
|
|
temps_valide = CASE WHEN type_evenement = 1 THEN temps_travail_geocom ELSE 0 END, -- Temps travail
|
|
temps_valide_ajuste = CASE WHEN type_evenement = 1 THEN temps_travail_geocom ELSE 0 END, -- Temps travail
|
|
temps_absence = CASE WHEN type_evenement = 2 THEN temps_absence_geocom ELSE 0 END, -- Temps travail
|
|
temps_absence_ajuste = CASE WHEN type_evenement = 2 THEN temps_absence_geocom ELSE 0 END -- Temps travail
|
|
;
|
|
|
|
-- Création d'index.
|
|
CREATE INDEX w_planning_i_day ON w_planning USING btree (day)
|
|
;
|
|
CREATE INDEX w_planning_i_idpers ON w_planning USING btree (idpers)
|
|
;
|
|
CREATE INDEX w_planning_i_salarie_id ON w_planning USING btree (salarie_id)
|
|
;
|
|
|
|
ANALYZE w_planning
|
|
;
|
|
|
|
]]></sqlcmd>
|
|
</NODE>
|
|
<NODE label="Gestion des qualifications des salariés">
|
|
<sqlcmd><![CDATA[
|
|
|
|
DROP TABLE IF EXISTS w_qualifications_salaries
|
|
;
|
|
|
|
CREATE TEMP TABLE w_qualifications_salaries AS
|
|
with hierarchie_qualifications AS (
|
|
SELECT
|
|
persqual.idpers,
|
|
array_agg(name ORDER BY persqual.orders) AS name,
|
|
array_agg(abr ORDER BY persqual.orders) AS abr
|
|
FROM prod_geocom.persqual
|
|
LEFT JOIN prod_geocom.berufe ON berufe.idberufe = persqual.idberufe
|
|
WHERE berufe.isdeleted = 0
|
|
GROUP BY persqual.idpers
|
|
ORDER BY persqual.idpers
|
|
)
|
|
SELECT
|
|
w_salaries.idpers,
|
|
hierarchie_qualifications.name[2] AS texte,
|
|
hierarchie_qualifications.abr[2] AS code
|
|
FROM w_salaries
|
|
LEFT JOIN hierarchie_qualifications ON hierarchie_qualifications.idpers = w_salaries.idpers
|
|
;
|
|
|
|
UPDATE w_planning
|
|
SET qualification_code = w_qualifications_salaries.code
|
|
FROM w_qualifications_salaries
|
|
WHERE w_planning.idpers = w_qualifications_salaries.idpers
|
|
|
|
]]></sqlcmd>
|
|
</NODE>
|
|
<NODE label="Gestion des services des salariés">
|
|
<sqlcmd><![CDATA[
|
|
|
|
DROP TABLE IF EXISTS w_services_salaries
|
|
;
|
|
|
|
CREATE TEMP TABLE w_services_salaries AS
|
|
SELECT
|
|
dplan.IDPERS,
|
|
dplan.DAY,
|
|
array_agg(dplanstat.idstat ORDER BY percents DESC) AS all_stations,
|
|
array_agg(dplanstat.percents ORDER BY percents DESC) AS all_percents,
|
|
array_agg(dplanstat.hours ORDER BY percents DESC) AS all_hours
|
|
FROM prod_geocom.dplan
|
|
JOIN prod_geocom.dplanabr ON dplanabr.idpers = dplan.idpers AND dplanabr.day = dplan.day -- Attachement de l'abbraviation (code travail/absence)
|
|
JOIN prod_geocom.DPLANSTAT ON DPLANSTAT.idpers = dplan.idpers AND DPLANSTAT.day = dplan.day
|
|
GROUP BY dplan.idpers, dplan.day
|
|
;
|
|
|
|
UPDATE w_planning
|
|
SET service_code = all_stations[1], niveau_code = all_stations[1]
|
|
FROM w_services_salaries
|
|
WHERE w_planning.idpers = w_services_salaries.idpers AND w_planning.day = w_services_salaries.day
|
|
;
|
|
|
|
]]></sqlcmd>
|
|
</NODE>
|
|
<NODE label="Attribution des contrats des salariés">
|
|
<sqlcmd><![CDATA[
|
|
|
|
-- Association aux contrats et contrat_mois.
|
|
-- En général, les heures planning sont effectuées AVANT un contrat/paie à cause du décallage avec la paie :
|
|
-- => les heures effectuées en fin de mois sont à associer avec le mois suivant.
|
|
with w_asso as (
|
|
select
|
|
cptres1_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
|
|
from w_planning
|
|
join rh.p_contrats_mois on 1=1
|
|
and p_contrats_mois.salarie_id = w_planning.salarie_id
|
|
and w_planning.date between p_contrats_mois.date_debut and p_contrats_mois.date_fin -- Sélection des contrats pendant heures planning.
|
|
where 1!=1
|
|
OR w_planning.contrat_id is null
|
|
OR w_planning.contrat_mois_id is null
|
|
group by 1)
|
|
UPDATE w_planning SET
|
|
contrat_id = w_asso.contrat_id,
|
|
contrat_mois_id = w_asso.contrat_mois_id
|
|
FROM w_asso
|
|
WHERE w_planning.cptres1_id = w_asso.cptres1_id
|
|
;
|
|
|
|
with w_asso as (
|
|
select
|
|
cptres1_id,
|
|
(min(array[extract(epoch from p_contrats_mois.date_debut), p_contrats_mois.contrat_id]))[2] as contrat_id,
|
|
(min(array[extract(epoch from p_contrats_mois.date_debut), p_contrats_mois.oid]))[2] as contrat_mois_id
|
|
from w_planning
|
|
join rh.p_contrats_mois on 1=1
|
|
and p_contrats_mois.salarie_id = w_planning.salarie_id
|
|
and p_contrats_mois.date_debut > w_planning.date -- Sélection des contrats APRES heures planning.
|
|
where 1!=1
|
|
OR w_planning.contrat_id is null
|
|
OR w_planning.contrat_mois_id is null
|
|
group by 1)
|
|
UPDATE w_planning SET
|
|
contrat_id = w_asso.contrat_id,
|
|
contrat_mois_id = w_asso.contrat_mois_id
|
|
FROM w_asso
|
|
WHERE w_planning.cptres1_id = w_asso.cptres1_id
|
|
;
|
|
|
|
with w_asso as (
|
|
select
|
|
cptres1_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
|
|
from w_planning
|
|
join rh.p_contrats_mois on 1=1
|
|
and p_contrats_mois.salarie_id = w_planning.salarie_id
|
|
and p_contrats_mois.date_debut < w_planning.date -- Sélection des contrats AVANT heures planning.
|
|
where 1!=1
|
|
OR w_planning.contrat_id is null
|
|
OR w_planning.contrat_mois_id is null
|
|
group by 1)
|
|
UPDATE w_planning SET
|
|
contrat_id = w_asso.contrat_id,
|
|
contrat_mois_id = w_asso.contrat_mois_id
|
|
FROM w_asso
|
|
WHERE w_planning.cptres1_id = w_asso.cptres1_id
|
|
;
|
|
|
|
]]></sqlcmd>
|
|
</NODE>
|
|
<NODE label="Alimentation des différentes tables de paramétres">
|
|
<sqlcmd><![CDATA[
|
|
|
|
-- Alimentation des tables de paramètres.
|
|
-- Màj des Services du Planning.
|
|
INSERT INTO rh.t_planning_service(code_original, code, texte, texte_court, service_id)
|
|
SELECT
|
|
idstation,
|
|
idstation,
|
|
name,
|
|
name,
|
|
0
|
|
FROM prod_geocom.stations
|
|
WHERE
|
|
NOT EXISTS (SELECT code_original FROM rh.t_planning_service WHERE code_original = idstation) AND
|
|
(idstation IS NOT NULL AND idstation != 0)
|
|
GROUP BY idstation, name
|
|
ORDER BY idstation
|
|
;
|
|
|
|
-- Màj des Niveaux du Planning.
|
|
-- Insertion des nouveaux niveaux de planning.
|
|
INSERT INTO rh.t_planning_niveau(code_original, code, texte, texte_court)
|
|
SELECT
|
|
idstation,
|
|
idstation,
|
|
name,
|
|
name
|
|
FROM prod_geocom.stations
|
|
WHERE
|
|
NOT EXISTS (SELECT code_original FROM rh.t_planning_niveau WHERE code_original = idstation) AND
|
|
(idstation IS NOT NULL AND idstation != 0)
|
|
GROUP BY idstation, name
|
|
ORDER BY idstation
|
|
;
|
|
|
|
-- Màj des Qualifications du Planning.
|
|
INSERT INTO rh.t_planning_qualification(code_original, code, texte, texte_court)
|
|
SELECT
|
|
code,
|
|
code,
|
|
texte,
|
|
texte
|
|
FROM w_qualifications_salaries
|
|
WHERE
|
|
code IS NOT NULL AND
|
|
NOT EXISTS (SELECT code_original FROM rh.t_planning_qualification WHERE code_original = code)
|
|
GROUP BY code, texte
|
|
ORDER BY code
|
|
;
|
|
|
|
-- Màj des Types d'absences du Planning.
|
|
INSERT INTO rh.t_planning_type_absence(code_original, code, texte, texte_court)
|
|
SELECT
|
|
abr,
|
|
abr,
|
|
name,
|
|
name
|
|
FROM prod_geocom.abwesend
|
|
WHERE
|
|
isdeleted = 0 AND
|
|
NOT EXISTS (SELECT code_original FROM rh.t_planning_type_absence WHERE code_original = abr) AND
|
|
(abr IS NOT NULL AND abr != '')
|
|
GROUP BY abr, name
|
|
ORDER BY abr
|
|
;
|
|
|
|
-- Màj des Codes Horaires du Planning.
|
|
INSERT INTO rh.t_planning_code_horaire(code_original, code, texte, texte_court)
|
|
SELECT
|
|
abr,
|
|
abr,
|
|
name,
|
|
name
|
|
FROM prod_geocom.dienste
|
|
WHERE
|
|
isdeleted = 0 AND
|
|
NOT EXISTS (SELECT code_original FROM rh.t_planning_code_horaire WHERE code_original = abr) AND
|
|
(abr IS NOT NULL AND abr != '')
|
|
GROUP BY abr, name
|
|
ORDER BY abr
|
|
;
|
|
|
|
]]></sqlcmd>
|
|
</NODE>
|
|
<NODE label="Alimentation de la table des mouvements du planning">
|
|
<sqlcmd><![CDATA[
|
|
|
|
-- Alimentation de la table de mouvement.
|
|
TRUNCATE rh.p_planning_mouvement
|
|
;
|
|
|
|
INSERT INTO rh.p_planning_mouvement(
|
|
salarie_id,
|
|
contrat_id,
|
|
contrat_mois_id,
|
|
date,
|
|
semaine,
|
|
mois,
|
|
etablissement_id, -- @todo à renseigner en fonction du paramétrage dans t_divers.
|
|
service_id,
|
|
qualification_id,
|
|
type_absence_id,
|
|
niveau_id,
|
|
code_horaire_id,
|
|
temps_du_initial,
|
|
temps_du,
|
|
temps_du_ajuste,
|
|
temps_valide,
|
|
temps_valide_ajuste,
|
|
temps_absence,
|
|
temps_absence_ajuste)
|
|
SELECT
|
|
w_planning.salarie_id,
|
|
w_planning.contrat_id,
|
|
w_planning.contrat_mois_id,
|
|
w_planning.date,
|
|
w_planning.semaine,
|
|
w_planning.mois,
|
|
coalesce(w_entets.etablissement_id, 0) AS etablissement_id,
|
|
coalesce(t_planning_service.oid, 0) AS service_id,
|
|
coalesce(t_planning_qualification.oid, 0) AS qualification_id,
|
|
coalesce(t_planning_type_absence.oid, 0) AS type_absence_id,
|
|
coalesce(t_planning_niveau.oid, 0) AS niveau_id,
|
|
coalesce(t_planning_code_horaire.oid, 0) AS code_horaire_id,
|
|
temps_du_initial,
|
|
temps_du,
|
|
temps_du_ajuste,
|
|
temps_valide,
|
|
temps_valide_ajuste,
|
|
temps_absence,
|
|
temps_absence_ajuste
|
|
FROM w_planning
|
|
JOIN rh.p_salaries ON p_salaries.oid = w_planning.salarie_id
|
|
JOIN w_entets ON w_entets.entreprise_id = p_salaries.entreprise_id
|
|
LEFT JOIN rh.t_planning_niveau ON t_planning_niveau.code_original = w_planning.niveau_code--_original
|
|
LEFT JOIN rh.t_planning_service ON t_planning_service.code_original = w_planning.service_code--_original
|
|
LEFT JOIN rh.t_planning_qualification ON t_planning_qualification.code_original = w_planning.qualification_code
|
|
LEFT JOIN rh.t_planning_type_absence ON t_planning_type_absence.code_original = w_planning.absence_code
|
|
LEFT JOIN rh.t_planning_code_horaire ON t_planning_code_horaire.code_original = w_planning.horaire_code
|
|
GROUP BY 1,2,3,4,5,6,7,8,9,10,11,12,13,14,15,16,17,18,19
|
|
;
|
|
|
|
ANALYZE rh.p_planning_mouvement
|
|
;
|
|
|
|
]]></sqlcmd>
|
|
</NODE>
|
|
</NODE>
|
|
<NODE name="POST" type="common" />
|
|
<NODE name="VACUUM" type="common" />
|
|
</ROOT>
|