<?xml version="1.0" encoding="ISO-8859-1"?>
|
|
<ROOT>
|
|
<NODE name="PROD" label="Synchronisation données">
|
|
<NODE label="Interprétation de la structure">
|
|
<sqlcmd><![CDATA[
|
|
|
|
-- structure avec comme services les structures ou uep et les groupe d'uep (avec min sur id pour prendre ceux définis à la base)
|
|
DROP TABLE IF EXISTS w_structure;
|
|
CREATE TEMP TABLE w_structure AS
|
|
WITH uep_uep as (
|
|
SELECT
|
|
iduepesclave,
|
|
(MAX(ARRAY[dtcreation::text,iduepmaitre::text]))[2] as iduepmaitre
|
|
FROM prod_agiletime.UEP_UEP
|
|
GROUP BY 1)
|
|
SELECT
|
|
uep.iduep,
|
|
uep.nomabrege as uep_code,
|
|
uep.nom as uep_nom,
|
|
CASE WHEN count(*) = 1 THEN min(structure.idstructure) ELSE null END AS idstructure,
|
|
CASE WHEN count(*) = 1 THEN min(structure.code) ELSE null END as structure_code,
|
|
CASE WHEN count(*) = 1 THEN min(structure.nom) ELSE null END as structure_nom,
|
|
min(uep2.iduep) as iduepgroupe,
|
|
min(uep2.nomabrege) as uepgroupe_code,
|
|
min(uep2.nom) as uepgroupe_nom,
|
|
'0'::text AS site_code
|
|
FROM prod_agiletime.UEP
|
|
LEFT JOIN prod_agiletime.UEP_STRUCTURE ON UEP.iduep = UEP_STRUCTURE.iduep
|
|
LEFT JOIN prod_agiletime.STRUCTURE ON UEP_STRUCTURE.idstructure = STRUCTURE.idstructure
|
|
LEFT JOIN UEP_UEP ON UEP_UEP.iduepesclave = UEP.iduep
|
|
LEFT JOIN prod_agiletime.UEP UEP2 ON UEP2.iduep = iduepmaitre
|
|
GROUP BY 1,2,3
|
|
ORDER BY 2
|
|
;
|
|
|
|
|
|
-- mise à jourd des structure manquantes avec min sur l'id structure
|
|
WITH uep_structure AS (
|
|
SELECT
|
|
iduep,
|
|
(MAX(ARRAY[dtfin::text,idstructure::text]))[2] as idstructure
|
|
FROM
|
|
prod_agiletime.UEP_STRUCTURE
|
|
GROUP BY 1)
|
|
UPDATE w_structure
|
|
SET
|
|
idstructure = STRUCTURE.idstructure,
|
|
structure_code = STRUCTURE.code,
|
|
structure_nom = STRUCTURE.nom
|
|
FROM uep_structure
|
|
LEFT JOIN prod_agiletime.STRUCTURE ON uep_structure.idstructure = STRUCTURE.idstructure
|
|
WHERE 1=1 AND
|
|
w_structure.iduep = uep_structure.iduep --AND
|
|
--(w_structure.idstructure IS NULL OR w_structure.idstructure = 1) AND
|
|
--idtypestructure != site_code
|
|
;
|
|
|
|
-- mise à jour des structures multiples à partir des liens avec salarie
|
|
-- UPDATE w_structure
|
|
-- SET
|
|
-- idstructure = sub.idstructure,
|
|
-- structure_code = sub.code,
|
|
-- structure_nom = sub.nom
|
|
-- FROM (
|
|
-- SELECT UEP.iduep,STRUCTURE.idstructure,STRUCTURE.code,STRUCTURE.nom
|
|
-- FROM prod_agiletime.SALARIE
|
|
-- LEFT JOIN prod_agiletime.SALARIE_STRUCTURE ON SALARIE.idsalarie = SALARIE_STRUCTURE.idsalarie
|
|
-- LEFT JOIN prod_agiletime.STRUCTURE ON SALARIE_STRUCTURE.idstructure = STRUCTURE.idstructure
|
|
-- LEFT JOIN prod_agiletime.SALARIE_UEP ON SALARIE_UEP.idsalarie = SALARIE.idsalarie
|
|
-- LEFT JOIN prod_agiletime.UEP ON UEP.iduep = SALARIE_UEP.iduep
|
|
-- WHERE idtypestructure != 1
|
|
-- GROUP BY 1,2,3,4
|
|
-- ORDER BY 1
|
|
-- ) sub
|
|
-- WHERE 1=1 AND
|
|
-- w_structure.iduep = sub.iduep AND
|
|
-- (w_structure.idstructure IS NULL OR
|
|
-- w_structure.idstructure = 1)
|
|
-- ;
|
|
-- mise à vide du code original pour lier avec non renseigné et forcage du code planning etablissement
|
|
UPDATE w_structure
|
|
SET
|
|
idstructure = CASE WHEN w_structure.idstructure IS NULL OR w_structure.idstructure = t_etablissements.planning_code THEN NULL ELSE w_structure.idstructure END,
|
|
site_code = t_etablissements.planning_code
|
|
FROM rh.t_entreprises
|
|
JOIN rh.t_etablissements ON t_etablissements.entreprise_id = t_entreprises.oid
|
|
LEFT JOIN prod_agiletime.structure ON structure.code = t_etablissements.planning_code OR (
|
|
(SELECT count(*) FROM prod_agiletime.structure JOIN rh.t_etablissements ON planning_code != '' AND planning_code = structure.code) = 0 AND structure.idstructure = t_etablissements.planning_code)
|
|
LEFT JOIN prod_agiletime.structure structure2 ON structure.idstructure = structure2.idstructurepere
|
|
LEFT JOIN prod_agiletime.structure structure3 ON structure2.idstructure = structure3.idstructurepere
|
|
LEFT JOIN prod_agiletime.structure structure4 ON structure3.idstructure = structure4.idstructurepere
|
|
LEFT JOIN prod_agiletime.structure structure5 ON structure4.idstructure = structure5.idstructurepere
|
|
WHERE 1=1 AND
|
|
t_etablissements.planning_code != '' AND
|
|
(
|
|
w_structure.idstructure = structure.idstructure OR
|
|
w_structure.idstructure = structure2.idstructure OR
|
|
w_structure.idstructure = structure3.idstructure OR
|
|
w_structure.idstructure = structure4.idstructure OR
|
|
w_structure.idstructure = structure5.idstructure
|
|
)
|
|
;
|
|
|
|
UPDATE w_structure
|
|
SET
|
|
idstructure = CASE WHEN w_structure.idstructure IS NULL OR w_structure.idstructure = t_etablissements.planning_code THEN NULL ELSE w_structure.idstructure END,
|
|
site_code = t_etablissements.planning_code
|
|
FROM rh.t_entreprises
|
|
JOIN rh.t_etablissements ON t_etablissements.entreprise_id = t_entreprises.oid
|
|
WHERE 1=1 AND
|
|
t_etablissements.planning_code != '' AND
|
|
(SELECT count(*) FROM prod_agiletime.structure JOIN rh.t_etablissements ON planning_code != '' AND planning_code = structure.code) = 0
|
|
;
|
|
|
|
DELETE from w_structure WHERE site_code != ALL(ARRAY(SELECT planning_code FROM rh.t_etablissements WHERE planning_code != '')::text[]);
|
|
]]></sqlcmd>
|
|
</NODE>
|
|
<NODE label="Import planning">
|
|
<sqlcmd><![CDATA[
|
|
|
|
|
|
-- Recensement des salariés et établissements.
|
|
DROP TABLE IF EXISTS w_sal_pla
|
|
;
|
|
CREATE TEMP TABLE w_sal_pla AS
|
|
SELECT
|
|
p_salaries.oid AS salarie_id,
|
|
p_salaries.matricule,
|
|
t_entreprises.code_original AS entreprise_code_original,
|
|
t_etablissements.code_original AS etablissement_code_original,
|
|
t_entreprises.code AS entreprise_code,
|
|
t_entreprises.planning_code AS entreprise_planning_code,
|
|
t_etablissements.code AS etablissement_code,
|
|
t_etablissements.planning_code as etablissement_planning_code, -- Pour cas 3 Sage
|
|
lpad(t_entreprises.code, 3, '0') || lpad(t_etablissements.code, 3, '0') || p_salaries.matricule AS matricule_planning, -- Pour cas 2 SHS
|
|
lpad(t_entreprises.planning_code, 3, '0') || lpad(t_etablissements.planning_code, 3, '0') || substr(p_salaries.matricule, 1, 5) AS matricule_planning_conso, -- Pour cas 5 SHS consolidé
|
|
ltrim(p_salaries.matricule, '0') AS matricule_trim, -- Pour cas 1 Cegid
|
|
''::text AS salarie_corr
|
|
FROM rh.p_salaries
|
|
-- Il faut absoluement faire le produit cartésien matricule/établissement même si un salarié n'a jamais travaillé dans un des établissement.
|
|
-- En effet, ce traitement pourrait ne pas remonter les données associées.
|
|
JOIN rh.t_entreprises ON t_entreprises.oid = p_salaries.entreprise_id
|
|
JOIN rh.t_etablissements ON t_etablissements.entreprise_id = p_salaries.entreprise_id
|
|
WHERE 1=1
|
|
AND salarie_fusionne_id = 0
|
|
GROUP BY 1,2,3,4,5,6,7,8,9,10,11,12
|
|
ORDER BY 1,2,3
|
|
;
|
|
|
|
-- Gestion des salariés fusionnés.
|
|
INSERT INTO w_sal_pla
|
|
SELECT
|
|
w_sal_pla.salarie_id,
|
|
p_salaries.matricule,
|
|
w_sal_pla.entreprise_code_original,
|
|
w_sal_pla.etablissement_code_original,
|
|
w_sal_pla.entreprise_code,
|
|
w_sal_pla.entreprise_planning_code,
|
|
w_sal_pla.etablissement_code,
|
|
w_sal_pla.etablissement_planning_code,
|
|
lpad(w_sal_pla.entreprise_code, 3, '0') || lpad(w_sal_pla.etablissement_code, 3, '0') || p_salaries.matricule AS matricule_planning,
|
|
lpad(w_sal_pla.entreprise_planning_code, 3, '0') || lpad(w_sal_pla.etablissement_planning_code, 3, '0') || substr(p_salaries.matricule, 1, 5) AS matricule_planning_conso,
|
|
ltrim(p_salaries.matricule, '0') AS matricule_trim,
|
|
''::text AS salarie_corr
|
|
FROM w_sal_pla
|
|
JOIN rh.p_salaries ON salarie_fusionne_id = w_sal_pla.salarie_id
|
|
WHERE salarie_fusionne_id != 0
|
|
;
|
|
|
|
-- Alimenter le champ w_sal_pla.salarie_corr.
|
|
UPDATE w_sal_pla SET
|
|
salarie_corr = matricule
|
|
;
|
|
|
|
-- Création d'index.
|
|
CREATE INDEX w_sal_pla_i_matricule ON w_sal_pla USING btree (matricule)
|
|
;
|
|
CREATE INDEX w_sal_pla_i_matricule_planning ON w_sal_pla USING btree (matricule_planning)
|
|
;
|
|
CREATE INDEX w_sal_pla_i_matricule_trim ON w_sal_pla USING btree (matricule_trim)
|
|
;
|
|
DROP TABLE IF EXISTS w_plan_base;
|
|
CREATE TEMP TABLE w_plan_base AS
|
|
|
|
|
|
SELECT
|
|
idplan,
|
|
affch.idaffch,
|
|
affch.idch,
|
|
ph.idph,
|
|
affch.idcycle_ch,
|
|
idtypologiech,
|
|
idtypecomportement,
|
|
affch.idsalarie,
|
|
dt,
|
|
affch.iduep,
|
|
affch.idcompetence,
|
|
ch_typeheure.idtypeheure AS chidtypeheure,
|
|
ph_typeheure.idtypeheure AS phidtypeheure,
|
|
debut AS debut_th,
|
|
fin AS fin_th,
|
|
duree AS duree_th,
|
|
dureejour,
|
|
0 AS doubleaff,
|
|
site_code
|
|
FROM prod_agiletime.AFFCH
|
|
JOIN w_structure ON affch.iduep = w_structure.iduep
|
|
JOIN rh.t_etablissements ON planning_code = site_code
|
|
JOIN prod_agiletime.CH ON CH.idch = AFFCH.idch AND AFFCH.idetat = 1
|
|
LEFT JOIN prod_agiletime.CH_TYPEHEURE ON CH.idch = CH_TYPEHEURE.idch AND CH_TYPEHEURE.idetat = 1
|
|
LEFT JOIN prod_agiletime.TYPEHEURE CHTYPEHEURE ON CH_TYPEHEURE.idtypeheure = CHTYPEHEURE.idtypeheure AND CH_TYPEHEURE.idetat = 1
|
|
LEFT JOIN prod_agiletime.PH_CH ON CH.idch = PH_CH.idch AND PH_CH.idetat = 1
|
|
LEFT JOIN prod_agiletime.PH ON PH.idph = PH_CH.idph AND PH.idetat = 1
|
|
LEFT JOIN prod_agiletime.PH_TYPEHEURE ON PH.idph = PH_TYPEHEURE.idph and PH_TYPEHEURE.idetat = 1
|
|
LEFT JOIN prod_agiletime.TYPEHEURE PHTYPEHEURE ON PH_TYPEHEURE.idtypeheure = PHTYPEHEURE.idtypeheure AND PHTYPEHEURE.idetat = 1
|
|
WHERE 1=1
|
|
AND idplan IN ('PPL','REF')
|
|
|
|
--AND AFFCH.valider = 1
|
|
;
|
|
|
|
INSERT INTO w_plan_base
|
|
SELECT
|
|
idplan,
|
|
affch.idaffch,
|
|
ph.idph,
|
|
affch.idchdouble as idch,
|
|
affch.idcycle_ch,
|
|
idtypologiech,
|
|
idtypecomportement,
|
|
idsalarie,
|
|
dt,
|
|
affch.iduepdouble AS iduep,
|
|
affch.idcompetencedouble AS idcompetence,
|
|
ch_typeheure.idtypeheure AS chidtypeheure,
|
|
ph_typeheure.idtypeheure AS phidtypeheure,
|
|
debut AS debut_th,
|
|
fin AS fin_th,
|
|
duree AS duree_theo,
|
|
dureejour,
|
|
1 AS doubleaff,
|
|
site_code
|
|
FROM prod_agiletime.AFFCH
|
|
JOIN w_structure ON affch.iduep = w_structure.iduep
|
|
JOIN rh.t_etablissements ON planning_code = site_code
|
|
JOIN prod_agiletime.CH ON CH.idch = AFFCH.idchdouble AND AFFCH.idetat = 1
|
|
LEFT JOIN prod_agiletime.CH_TYPEHEURE ON CH.idch = CH_TYPEHEURE.idch AND CH_TYPEHEURE.idetat = 1
|
|
LEFT JOIN prod_agiletime.TYPEHEURE CHTYPEHEURE ON CH_TYPEHEURE.idtypeheure = CHTYPEHEURE.idtypeheure AND CH_TYPEHEURE.idetat = 1
|
|
LEFT JOIN prod_agiletime.PH_CH ON CH.idch = PH_CH.idch AND PH_CH.idetat = 1
|
|
LEFT JOIN prod_agiletime.PH ON PH.idph = PH_CH.idph AND PH.idetat = 1
|
|
LEFT JOIN prod_agiletime.PH_TYPEHEURE ON PH.idph = PH_TYPEHEURE.idph and PH_TYPEHEURE.idetat = 1
|
|
LEFT JOIN prod_agiletime.TYPEHEURE PHTYPEHEURE ON PH_TYPEHEURE.idtypeheure = PHTYPEHEURE.idtypeheure AND PHTYPEHEURE.idetat = 1
|
|
WHERE 1=1
|
|
AND idplan IN ('PPL','REF')
|
|
--AND AFFCH.valider = 1
|
|
;
|
|
|
|
-- ajustements des compétences avec celles du salarié si vide
|
|
UPDATE w_plan_base
|
|
SET
|
|
idcompetence = salarie_competence.idcompetence
|
|
FROM prod_agiletime.salarie_competence
|
|
WHERE 1=1
|
|
AND w_plan_base.idsalarie = salarie_competence.idsalarie
|
|
AND w_plan_base.idcompetence = 0
|
|
AND salarie_competence.idcompetence != 0
|
|
;
|
|
|
|
-- croisement avec les contrats et les personnes
|
|
DROP TABLE IF EXISTS w_plan_theo;
|
|
CREATE TEMP TABLE w_plan_theo AS
|
|
SELECT
|
|
w_plan_base.*,
|
|
matricule as salarie_corr,
|
|
numero
|
|
FROM w_plan_base
|
|
JOIN prod_agiletime.SALARIE ON SALARIE.idsalarie = w_plan_base.idsalarie and SALARIE.idetat = 1
|
|
JOIN prod_agiletime.SALARIE_CONTRAT ON SALARIE.idsalarie = SALARIE_CONTRAT.idsalarie AND SALARIE_CONTRAT.idetat = 1
|
|
JOIN prod_agiletime.CONTRAT ON SALARIE_CONTRAT.idcontrat = CONTRAT.idcontrat AND dt BETWEEN dtdebut AND (CASE WHEN dtfin != '1800-01-01' THEN dtfin ELSE '2099-12-31' END) AND CONTRAT.idetat = 1
|
|
WHERE 1=1
|
|
AND idplan ='PPL'
|
|
|
|
;
|
|
|
|
|
|
-- croisement avec les contrats et les personnes
|
|
DROP TABLE IF EXISTS w_plan_rea;
|
|
CREATE TEMP TABLE w_plan_rea AS
|
|
SELECT
|
|
w_plan_base.*,
|
|
matricule as salarie_corr,
|
|
numero,
|
|
affph.idaffph,
|
|
affph.doubleaff as affphdoubleaff,
|
|
CASE WHEN sub.idph IS NULL THEN heuredebut ELSE debut_th END as heuredebut,
|
|
CASE WHEN sub.idph IS NULL THEN heurefin ELSE fin_th END as heurefin,
|
|
CASE WHEN sub.idph IS NULL THEN duree ELSE duree_th - CASE WHEN duree_th > 250 THEN 30 ELSE 0 END END as duree
|
|
FROM w_plan_base
|
|
JOIN prod_agiletime.SALARIE ON SALARIE.idsalarie = w_plan_base.idsalarie and SALARIE.idetat = 1
|
|
JOIN prod_agiletime.SALARIE_CONTRAT ON SALARIE.idsalarie = SALARIE_CONTRAT.idsalarie AND SALARIE_CONTRAT.idetat = 1
|
|
JOIN prod_agiletime.CONTRAT ON SALARIE_CONTRAT.idcontrat = CONTRAT.idcontrat AND dt BETWEEN dtdebut AND (CASE WHEN dtfin != '1800-01-01' THEN dtfin ELSE '2099-12-31' END) AND CONTRAT.idetat = 1
|
|
LEFT JOIN prod_agiletime.AFFPH on AFFPH.idaffch = w_plan_base.idaffch and AFFPH.idetat = 1
|
|
-- cas Keraudren ou les plages sont divisées en deux
|
|
AND ((debut_th < fin_th) AND (AFFPH.heuredebut < fin_th AND AFFPH.heurefin > debut_th) OR (debut_th > fin_th) AND (AFFPH.heuredebut > fin_th AND AFFPH.heurefin < debut_th))
|
|
LEFT JOIN prod_agiletime.AFFPH_TYPEHEURE ON AFFPH.idaffph = AFFPH_TYPEHEURE.idaffph and AFFPH_TYPEHEURE.idetat = 1
|
|
LEFT JOIN (SELECT DISTINCT idph FROM prod_agiletime.ph_ecretage) sub on sub.idph = w_plan_base.idph
|
|
WHERE 1=1
|
|
-- séparation en deux PPL et REF enlève les abscences on garde donc PPL et il faudra voir à la qualif
|
|
AND idplan = 'PPL'
|
|
AND (AFFPH_TYPEHEURE.idtypeheure = phidtypeheure OR AFFPH_TYPEHEURE.idtypeheure IS NULL)
|
|
|
|
;
|
|
|
|
DELETE from w_plan_rea where doubleaff != -(AFFPHdoubleaff);
|
|
|
|
-- ajustements des durées avec les pauses
|
|
|
|
UPDATE w_plan_theo
|
|
SET
|
|
duree_th = w_plan_theo.duree_th - w_pauses.duree_th,
|
|
debut_th = CASE WHEN w_plan_theo.debut_th + w_pauses.duree_th < 1440 THEN w_plan_theo.debut_th + w_pauses.duree_th ELSE w_plan_theo.debut_th END,
|
|
fin_th = CASE WHEN w_plan_theo.debut_th + w_pauses.duree_th >= 1440 THEN w_plan_theo.fin_th + w_pauses.duree_th ELSE w_plan_theo.fin_th END
|
|
FROM w_plan_theo w_pauses
|
|
|
|
|
|
WHERE 1=1
|
|
AND w_pauses.phidtypeheure = ANY(regexp_split_to_array((SELECT valeur FROM rh.t_divers WHERE code = 'AGILETIME_PAUSE'),','))
|
|
AND w_plan_theo.idaffch = w_pauses.idaffch
|
|
AND w_plan_theo.doubleaff = w_pauses.doubleaff
|
|
AND w_plan_theo.phidtypeheure != ALL(regexp_split_to_array((SELECT valeur FROM rh.t_divers WHERE code = 'AGILETIME_PAUSE'),','))
|
|
|
|
|
|
|
|
;
|
|
|
|
|
|
UPDATE w_plan_rea
|
|
SET
|
|
duree = w_plan_rea.duree - w_pauses.duree,
|
|
|
|
heuredebut = CASE WHEN w_plan_rea.heuredebut + w_pauses.duree < 1440 THEN w_plan_rea.heuredebut + w_pauses.duree ELSE w_plan_rea.heuredebut END,
|
|
|
|
heurefin = CASE WHEN w_plan_rea.heuredebut + w_pauses.duree >= 1440 THEN w_plan_rea.heurefin + w_pauses.duree ELSE w_plan_rea.heurefin END
|
|
|
|
FROM w_plan_rea w_pauses
|
|
WHERE 1=1
|
|
AND w_pauses.phidtypeheure = ANY(regexp_split_to_array((SELECT valeur FROM rh.t_divers WHERE code = 'AGILETIME_PAUSE'),','))
|
|
|
|
AND w_plan_rea.idaffch = w_pauses.idaffch
|
|
AND w_plan_rea.doubleaff = w_pauses.doubleaff
|
|
AND w_plan_rea.phidtypeheure != ALL(regexp_split_to_array((SELECT valeur FROM rh.t_divers WHERE code = 'AGILETIME_PAUSE'),','))
|
|
|
|
;
|
|
|
|
DELETE FROM w_plan_theo WHERE phidtypeheure = ANY(regexp_split_to_array((SELECT valeur FROM rh.t_divers WHERE code = 'AGILETIME_PAUSE'),','));
|
|
DELETE FROM w_plan_rea WHERE phidtypeheure = ANY(regexp_split_to_array((SELECT valeur FROM rh.t_divers WHERE code = 'AGILETIME_PAUSE'),','));
|
|
|
|
;
|
|
|
|
--effacement des avenants
|
|
DELETE FROM w_plan_rea WHERE phidtypeheure = ANY(regexp_split_to_array((SELECT valeur FROM rh.t_divers WHERE code = 'AGILETIME_TODEL'),','));
|
|
;
|
|
DELETE FROM w_plan_theo WHERE phidtypeheure = ANY(regexp_split_to_array((SELECT valeur FROM rh.t_divers WHERE code = 'AGILETIME_TODEL'),','));
|
|
|
|
;
|
|
|
|
DROP SEQUENCE IF EXISTS w_cptres1_seq
|
|
;
|
|
|
|
CREATE TEMP SEQUENCE w_cptres1_seq
|
|
;
|
|
|
|
DROP TABLE IF EXISTS w_cptres1
|
|
;
|
|
-- heures travaillees = temps valide
|
|
CREATE TEMP TABLE w_cptres1 AS
|
|
SELECT
|
|
nextval('w_cptres1_seq') as cptres1_id,
|
|
matricule,
|
|
salarie_id,
|
|
numero,
|
|
null::bigint AS contrat_id,
|
|
null::bigint AS contrat_mois_id,
|
|
date(dt) AS date,
|
|
date(dt) AS date_orig,
|
|
duree/60.0 AS temps_orig,
|
|
idcompetence,
|
|
iduep,
|
|
''::text AS abs_cod,
|
|
0::numeric AS temps_du_initial,
|
|
0::numeric AS temps_du,
|
|
CASE WHEN heurefin >= heuredebut AND (duree < 1440 OR duree is null) THEN heurefin - heuredebut ELSE (1440 - heuredebut) END/60.0 AS temps_valide,
|
|
0::numeric AS temps_absence
|
|
FROM w_plan_rea
|
|
JOIN w_sal_pla ON w_sal_pla.matricule = w_plan_rea.salarie_corr AND etablissement_planning_code = site_code
|
|
WHERE 1=1
|
|
AND idtypologiech IN (1,4)
|
|
AND idtypecomportement = 1
|
|
ORDER BY 2,7
|
|
;
|
|
|
|
INSERT INTO w_cptres1
|
|
SELECT
|
|
nextval('w_cptres1_seq') as cptres1_id,
|
|
matricule,
|
|
salarie_id,
|
|
numero,
|
|
null::bigint AS contrat_id,
|
|
null::bigint AS contrat_mois_id,
|
|
date(dt) + interval '1 day' AS date,
|
|
date(dt) AS date_orig,
|
|
duree / 60.0 AS temps_orig,
|
|
idcompetence,
|
|
iduep,
|
|
''::text AS abs_cod,
|
|
0 AS temps_du_initial,
|
|
0 AS temps_du,
|
|
heurefin / 60.0 AS temps_valide,
|
|
0::numeric AS temps_absence
|
|
FROM w_plan_rea
|
|
JOIN w_sal_pla ON w_sal_pla.matricule = w_plan_rea.salarie_corr AND etablissement_planning_code = site_code
|
|
WHERE 1=1
|
|
AND idtypologiech IN (1,4)
|
|
AND idtypecomportement = 1
|
|
AND (heurefin < heuredebut OR duree > 1440)
|
|
ORDER BY 2,7
|
|
;
|
|
|
|
-- heures planifiées = temps du intial
|
|
INSERT INTO w_cptres1
|
|
SELECT
|
|
nextval('w_cptres1_seq') as cptres1_id,
|
|
matricule,
|
|
salarie_id,
|
|
numero,
|
|
null::bigint AS contrat_id,
|
|
null::bigint AS contrat_mois_id,
|
|
date(dt) AS date,
|
|
date(dt) AS date_orig,
|
|
duree_th / 60.0 AS temps_orig,
|
|
idcompetence,
|
|
iduep,
|
|
''::text AS abs_cod,
|
|
CASE WHEN fin_th >= debut_th AND duree_th < 1440 THEN duree_th ELSE (1440 - debut_th) END/60.0 AS temps_du_initial,
|
|
0 AS temps_du,
|
|
0 AS temps_valide,
|
|
0::numeric AS temps_absence
|
|
FROM w_plan_theo
|
|
JOIN w_sal_pla ON w_sal_pla.matricule = w_plan_theo.salarie_corr AND etablissement_planning_code = site_code
|
|
WHERE 1=1
|
|
AND idtypologiech IN (1,4)
|
|
AND idtypecomportement = 1
|
|
ORDER BY 2,7
|
|
;
|
|
|
|
INSERT INTO w_cptres1
|
|
SELECT
|
|
nextval('w_cptres1_seq') as cptres1_id,
|
|
matricule,
|
|
salarie_id,
|
|
numero,
|
|
null::bigint AS contrat_id,
|
|
null::bigint AS contrat_mois_id,
|
|
date(dt) + interval '1 day' AS date,
|
|
date(dt) AS date_orig,
|
|
duree_th / 60.0 AS temps_orig,
|
|
idcompetence,
|
|
iduep,
|
|
''::text AS abs_cod,
|
|
fin_th / 60.0 AS temps_du_initial,
|
|
0 AS temps_du,
|
|
0 AS temps_valide,
|
|
0::numeric AS temps_absence
|
|
FROM w_plan_theo
|
|
JOIN w_sal_pla ON w_sal_pla.matricule = w_plan_theo.salarie_corr AND etablissement_planning_code = site_code
|
|
WHERE 1=1
|
|
AND idtypologiech IN (1,4)
|
|
AND idtypecomportement = 1
|
|
AND (fin_th < debut_th OR duree_th > 1440)
|
|
ORDER BY 2,7
|
|
;
|
|
|
|
|
|
-- absences
|
|
INSERT INTO w_cptres1
|
|
SELECT
|
|
nextval('w_cptres1_seq') as cptres1_id,
|
|
matricule,
|
|
salarie_id,
|
|
numero,
|
|
null::bigint AS contrat_id,
|
|
null::bigint AS contrat_mois_id,
|
|
date(dt) AS date,
|
|
date(dt) AS date_orig,
|
|
duree / 60.0 AS temps_orig,
|
|
idcompetence,
|
|
iduep,
|
|
idch AS abs_cod,
|
|
0 AS temps_du_initial,
|
|
0 AS temps_du,
|
|
0 AS temps_valide,
|
|
CASE WHEN heurefin > heuredebut THEN duree
|
|
WHEN heurefin < heuredebut THEN (1440 - heuredebut)
|
|
WHEN heurefin = heuredebut AND duree != 0 THEN duree
|
|
ELSE dureejour END/60.0 AS temps_absence
|
|
FROM w_plan_rea
|
|
JOIN w_sal_pla ON w_sal_pla.matricule = w_plan_rea.salarie_corr AND etablissement_planning_code = site_code
|
|
WHERE 1=1
|
|
AND idtypologiech = 2
|
|
AND idtypecomportement IN (1,8,9)
|
|
ORDER BY 2,7
|
|
;
|
|
|
|
INSERT INTO w_cptres1
|
|
SELECT
|
|
nextval('w_cptres1_seq') as cptres1_id,
|
|
matricule,
|
|
salarie_id,
|
|
numero,
|
|
null::bigint AS contrat_id,
|
|
null::bigint AS contrat_mois_id,
|
|
date(dt) + interval '1 day' AS date,
|
|
date(dt) AS date_orig,
|
|
duree_th / 60.0 AS temps_orig,
|
|
idcompetence,
|
|
iduep,
|
|
idch AS abs_cod,
|
|
0 AS temps_du_initial,
|
|
0 AS temps_du,
|
|
0 AS temps_valide,
|
|
heurefin/60.0 AS temps_absence
|
|
FROM w_plan_rea
|
|
JOIN w_sal_pla ON w_sal_pla.matricule = w_plan_rea.salarie_corr AND etablissement_planning_code = site_code
|
|
WHERE 1=1
|
|
AND idtypologiech = 2
|
|
AND idtypecomportement IN (1,8,9)
|
|
AND heurefin < heuredebut
|
|
ORDER BY 2,7
|
|
;
|
|
|
|
UPDATE w_cptres1
|
|
SET date = date_orig
|
|
FROM rh.t_divers
|
|
WHERE
|
|
code = 'VENTIL_JOUR'
|
|
AND valeur = 0;
|
|
|
|
|
|
VACUUM ANALYSE w_cptres1
|
|
;
|
|
|
|
-- 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_cptres1
|
|
join rh.p_contrats_mois on 1=1
|
|
and p_contrats_mois.salarie_id = w_cptres1.salarie_id
|
|
and w_cptres1.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_cptres1.contrat_id is null
|
|
OR w_cptres1.contrat_mois_id is null
|
|
group by 1)
|
|
UPDATE w_cptres1 SET
|
|
contrat_id = w_asso.contrat_id,
|
|
contrat_mois_id = w_asso.contrat_mois_id
|
|
FROM w_asso
|
|
WHERE w_cptres1.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_cptres1
|
|
join rh.p_contrats_mois on 1=1
|
|
and p_contrats_mois.salarie_id = w_cptres1.salarie_id
|
|
and p_contrats_mois.date_debut > w_cptres1.date -- Sélection des contrats APRES heures planning.
|
|
WHERE 1=1
|
|
OR w_cptres1.contrat_id is null
|
|
OR w_cptres1.contrat_mois_id is null
|
|
group by 1)
|
|
UPDATE w_cptres1 SET
|
|
contrat_id = w_asso.contrat_id,
|
|
contrat_mois_id = w_asso.contrat_mois_id
|
|
FROM w_asso
|
|
WHERE w_cptres1.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_cptres1
|
|
join rh.p_contrats_mois on 1=1
|
|
and p_contrats_mois.salarie_id = w_cptres1.salarie_id
|
|
and p_contrats_mois.date_debut < w_cptres1.date -- Sélection des contrats AVANT heures planning.
|
|
WHERE 1=1
|
|
OR w_cptres1.contrat_id is null
|
|
OR w_cptres1.contrat_mois_id is null
|
|
group by 1)
|
|
UPDATE w_cptres1 SET
|
|
contrat_id = w_asso.contrat_id,
|
|
contrat_mois_id = w_asso.contrat_mois_id
|
|
FROM w_asso
|
|
WHERE w_cptres1.cptres1_id = w_asso.cptres1_id
|
|
;
|
|
|
|
-- Création d'index.
|
|
CREATE INDEX w_cptres1_i_contrat_id ON w_cptres1 USING btree (contrat_id)
|
|
;
|
|
CREATE INDEX w_cptres1_i_contrat_mois_id ON w_cptres1 USING btree (contrat_mois_id)
|
|
;
|
|
CREATE INDEX w_cptres1_i_date ON w_cptres1 USING btree (date)
|
|
;
|
|
CREATE INDEX w_cptres1_i_salarie_id ON w_cptres1 USING btree (salarie_id)
|
|
;
|
|
|
|
-- Alimentation des tables de paramètres.
|
|
|
|
INSERT INTO rh.t_divers(
|
|
code,
|
|
texte,
|
|
valeur,
|
|
valeur_date,
|
|
description)
|
|
-- Ajout du paramétrage permettant de choisir le niveau intermédiaire Agiletime
|
|
SELECT
|
|
'AGILETIME_NIV2',
|
|
'Niveau intermédiaire dans Agiletime (0 ou 1).',
|
|
'1',
|
|
NULL::date,
|
|
'(0) Groupe d''UEP (1) Structure'
|
|
WHERE (SELECT count(*) FROM rh.t_divers WHERE code = 'AGILETIME_NIV2') = 0
|
|
;
|
|
|
|
-- Màj des Services du Planning. (UEP)
|
|
INSERT INTO rh.t_planning_service(code_original, code, texte, texte_court, service_id)
|
|
WITH services AS (
|
|
SELECT
|
|
iduep,
|
|
idstructure AS id,
|
|
structure_code AS code,
|
|
structure_nom as texte
|
|
FROM w_structure
|
|
JOIN rh.t_divers ON code ='AGILETIME_NIV2' AND valeur = '1'
|
|
UNION ALL
|
|
SELECT
|
|
iduep,
|
|
iduepgroupe AS id,
|
|
uepgroupe_code::text AS code,
|
|
uepgroupe_nom AS texte
|
|
FROM w_structure
|
|
JOIN rh.t_divers ON code ='AGILETIME_NIV2' AND valeur = '0'
|
|
UNION ALL
|
|
SELECT
|
|
null AS iduep,
|
|
0 AS id,
|
|
'NR' AS code,
|
|
'Non renseigné' as texte
|
|
)
|
|
SELECT id, code, texte, texte, (select oid from rh.t_classes where code = 'PLANIV2') as classe_id
|
|
FROM services
|
|
WHERE id IS NOT NULL AND
|
|
id NOT IN (SELECT code_original FROM rh.t_planning_service WHERE code_original IS NOT NULL)
|
|
AND (iduep IN (SELECT iduep FROM w_cptres1 GROUP BY 1) OR iduep IS NULL)
|
|
GROUP BY 1,2,3,4
|
|
;
|
|
|
|
-- Màj des Niveaux du Planning. (UEP)
|
|
DROP TABLE IF EXISTS w_niv_uep;
|
|
CREATE TEMP TABLE w_niv_uep AS
|
|
SELECT
|
|
iduep,
|
|
site_code||'|'||COALESCE(CASE WHEN COALESCE(valeur::int,0) = 0 THEN uepgroupe_code ELSE structure_code END,'NR') ||'|'||uep_code||CASE WHEN rank() OVER (PARTITION BY uep_code ORDER BY iduep) > 1 THEN '_2' ELSE '' END as code_original,
|
|
uep_code,
|
|
uep_nom
|
|
FROM w_structure
|
|
LEFT JOIN rh.t_divers ON code ='AGILETIME_NIV2'
|
|
;
|
|
|
|
INSERT INTO rh.t_planning_niveau(code_original, code, texte, texte_court)
|
|
SELECT
|
|
code_original,
|
|
uep_code,
|
|
uep_nom,
|
|
substr(uep_nom,1,50)
|
|
FROM w_niv_uep
|
|
WHERE code_original NOT IN (SELECT code_original FROM rh.t_planning_niveau WHERE code_original IS NOT NULL)
|
|
AND iduep IN (SELECT iduep FROM w_cptres1 GROUP BY 1)
|
|
;
|
|
|
|
-- Màj des Qualifications du Planning. (competence)
|
|
INSERT INTO rh.t_planning_qualification(code_original, code, texte, texte_court)
|
|
SELECT
|
|
idcompetence,
|
|
idcompetence,
|
|
nom,
|
|
nom
|
|
FROM prod_agiletime.COMPETENCE
|
|
WHERE 1=1
|
|
AND idcompetence IN (SELECT idcompetence FROM w_cptres1)
|
|
AND idcompetence NOT IN (SELECT code_original FROM rh.t_planning_qualification WHERE code_original IS NOT NULL)
|
|
;
|
|
|
|
-- Màj des Types d'absences du Planning. (ch)
|
|
INSERT INTO rh.t_planning_type_absence(code_original, code, texte, texte_court)
|
|
SELECT
|
|
idch,
|
|
nomabrege,
|
|
nom,
|
|
nom
|
|
FROM prod_agiletime.CH
|
|
WHERE 1=1
|
|
AND idch IN (SELECT abs_cod FROM w_cptres1 GROUP BY 1)
|
|
AND idch NOT IN (SELECT code_original FROM rh.t_planning_type_absence WHERE code_original IS NOT NULL)
|
|
;
|
|
|
|
-- Création d'une table Entreprise/Etablissement.
|
|
DROP TABLE IF EXISTS w_entets
|
|
;
|
|
|
|
CREATE TEMP TABLE w_entets AS
|
|
SELECT
|
|
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
|
|
;
|
|
|
|
DROP TABLE IF EXISTS w_ventil_structure;
|
|
CREATE TEMP TABLE w_ventil_structure AS
|
|
SELECT
|
|
idstructure,
|
|
code,
|
|
string_to_array(nom,' ') as codes,
|
|
string_to_array(code,'_')::int[] as coefs,
|
|
array_length(string_to_array(nom,' '),1) as nb_codes,
|
|
array_length(string_to_array(code,'_'),1) as nb_coefs,
|
|
(select sum(unnest) from (select unnest(string_to_array(code,'_')::int[])) sub) - split_part(code,'_',1)::int as coef_tot
|
|
FROM prod_agiletime.STRUCTURE
|
|
WHERE code ~ '_'
|
|
|
|
;
|
|
|
|
DROP TABLE IF EXISTS w_ventil_services;
|
|
CREATE TABLE w_ventil_services AS
|
|
SELECT
|
|
idstructure,
|
|
code_original,
|
|
texte,
|
|
coefs[nb_coefs] AS coef,
|
|
coef_tot
|
|
FROM w_ventil_structure
|
|
LEFT JOIN rh.t_planning_service ON
|
|
CASE WHEN codes[nb_codes] IN (SELECT left(code,4) FROM rh.t_planning_service) THEN left(t_planning_service.code,4) ELSE upper(replace(left(t_planning_service.texte,3),'é','e')) END = codes[nb_codes]
|
|
;
|
|
|
|
INSERT INTO w_ventil_services
|
|
SELECT
|
|
idstructure,
|
|
code_original,
|
|
texte,
|
|
coefs[nb_coefs-1] AS coef,
|
|
coef_tot
|
|
FROM w_ventil_structure
|
|
LEFT JOIN rh.t_planning_service ON
|
|
CASE WHEN codes[nb_codes-1] IN (SELECT left(code,4) FROM rh.t_planning_service) THEN left(t_planning_service.code,4) ELSE upper(replace(left(t_planning_service.texte,3),'é','e')) END = codes[nb_codes-1]
|
|
;
|
|
INSERT INTO w_ventil_services
|
|
SELECT
|
|
idstructure,
|
|
code_original,
|
|
texte,
|
|
coefs[nb_coefs-2] AS coef,
|
|
coef_tot
|
|
FROM w_ventil_structure
|
|
LEFT JOIN rh.t_planning_service ON
|
|
CASE WHEN codes[nb_codes-2] IN (SELECT left(code,4) FROM rh.t_planning_service) THEN left(t_planning_service.code,4) ELSE upper(replace(left(t_planning_service.texte,3),'é','e')) END = codes[nb_codes-2]
|
|
;
|
|
INSERT INTO w_ventil_services
|
|
SELECT
|
|
idstructure,
|
|
code_original,
|
|
texte,
|
|
coefs[nb_coefs-3] AS coef,
|
|
coef_tot
|
|
FROM w_ventil_structure
|
|
LEFT JOIN rh.t_planning_service ON
|
|
CASE WHEN codes[nb_codes-3] IN (SELECT left(code,4) FROM rh.t_planning_service) THEN left(t_planning_service.code,4) ELSE upper(replace(left(t_planning_service.texte,3),'é','e')) END = codes[nb_codes-3]
|
|
;
|
|
INSERT INTO w_ventil_services
|
|
SELECT
|
|
idstructure,
|
|
code_original,
|
|
texte,
|
|
coefs[nb_coefs-4] AS coef,
|
|
coef_tot
|
|
FROM w_ventil_structure
|
|
LEFT JOIN rh.t_planning_service ON
|
|
CASE WHEN codes[nb_codes-4] IN (SELECT left(code,4) FROM rh.t_planning_service) THEN left(t_planning_service.code,4) ELSE upper(replace(left(t_planning_service.texte,3),'é','e')) END = codes[nb_codes-4]
|
|
;
|
|
|
|
-- Alimentation de la table de mouvement.
|
|
-- 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,
|
|
temps_du,
|
|
temps_du_initial,
|
|
temps_valide,
|
|
temps_absence)
|
|
SELECT
|
|
salarie_id,
|
|
contrat_id,
|
|
contrat_mois_id,
|
|
date,
|
|
to_char(date, 'IYYYIW'::text)::numeric AS semaine,
|
|
to_char(date, 'YYYYMM'::text)::numeric AS 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,
|
|
temps_valide + temps_absence,
|
|
temps_du_initial,
|
|
temps_valide,
|
|
temps_absence
|
|
FROM w_cptres1
|
|
LEFT JOIN w_structure ON w_cptres1.iduep = w_structure.iduep
|
|
LEFT JOIN w_ventil_services ON w_structure.idstructure = w_ventil_services.idstructure
|
|
LEFT JOIN rh.t_planning_service ON t_planning_service.code_original = w_structure.idstructure
|
|
LEFT JOIN rh.t_planning_qualification ON t_planning_qualification.code_original = w_cptres1.idcompetence
|
|
LEFT JOIN rh.t_planning_type_absence ON t_planning_type_absence.code_original = w_cptres1.abs_cod
|
|
LEFT JOIN w_entets ON w_entets.entets_code = 1 -- w_cptres1.entets_code
|
|
LEFT JOIN w_niv_uep ON w_cptres1.iduep = w_niv_uep.iduep
|
|
LEFT JOIN rh.t_planning_niveau ON t_planning_niveau.code_original = w_niv_uep.code_original
|
|
LEFT JOIN rh.t_divers VENTIL_JOUR ON VENTIL_JOUR.code = 'VENTIL_JOUR'
|
|
WHERE w_ventil_services.idstructure IS NULL
|
|
;
|
|
|
|
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,
|
|
temps_du,
|
|
temps_du_initial,
|
|
temps_valide,
|
|
temps_absence)
|
|
SELECT
|
|
salarie_id,
|
|
contrat_id,
|
|
contrat_mois_id,
|
|
CASE WHEN COALESCE(VENTIL_JOUR.valeur::int,0) = 1 THEN date ELSE date_orig::date END,
|
|
to_char(w_cptres1.date, 'IYYYIW'::text)::numeric AS semaine,
|
|
to_char(w_cptres1.date, 'YYYYMM'::text)::numeric AS 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,
|
|
(temps_valide + temps_absence)*coef/coef_tot,
|
|
temps_du_initial*coef/coef_tot,
|
|
temps_valide*coef/coef_tot,
|
|
temps_absence*coef/coef_tot
|
|
FROM w_cptres1
|
|
LEFT JOIN w_structure ON w_cptres1.iduep = w_structure.iduep
|
|
LEFT JOIN w_ventil_services ON w_structure.idstructure = w_ventil_services.idstructure
|
|
JOIN rh.t_planning_service ON t_planning_service.code_original = w_ventil_services.code_original
|
|
LEFT JOIN rh.t_planning_qualification ON t_planning_qualification.code_original = w_cptres1.idcompetence
|
|
LEFT JOIN rh.t_planning_type_absence ON t_planning_type_absence.code_original = w_cptres1.abs_cod
|
|
LEFT JOIN w_entets ON w_entets.entets_code = 1 -- w_cptres1.entets_code
|
|
LEFT JOIN w_niv_uep ON w_cptres1.iduep = w_niv_uep.iduep
|
|
LEFT JOIN rh.t_planning_niveau ON t_planning_niveau.code_original = w_niv_uep.code_original
|
|
LEFT JOIN rh.t_divers VENTIL_JOUR ON VENTIL_JOUR.code = 'VENTIL_JOUR'
|
|
;
|
|
|
|
VACUUM ANALYSE rh.p_planning_mouvement
|
|
;
|
|
|
|
]]></sqlcmd>
|
|
</NODE>
|
|
</NODE>
|
|
<NODE name="POST" label="Post traitements">
|
|
<sqlcmd><![CDATA[
|
|
|
|
-- Lorsqu'il n'y a pas de liaison entre les Qualifications Paie/Planning,
|
|
-- essayer de faire un rapprochement par le code ET le libellé.
|
|
UPDATE rh.t_planning_qualification SET
|
|
qualification_id = t_qualifications.oid
|
|
FROM rh.t_qualifications
|
|
WHERE 1=1
|
|
AND t_qualifications.code = t_planning_qualification.code
|
|
AND t_planning_qualification.qualification_id = 0
|
|
AND substr(t_planning_qualification.texte, 1, 10) = substr(t_qualifications.texte, 1, 10)
|
|
;
|
|
|
|
-- Report des Qualification Paie sur Qualification Planning.
|
|
UPDATE rh.t_planning_qualification SET
|
|
qualification_code = t_qualifications.code,
|
|
qualification_texte = t_qualifications.texte_court,
|
|
qualification_section_id = t_qualifications.section_id,
|
|
qualification_section_code = t_qualifications.section_code,
|
|
qualification_section_texte = t_qualifications.section_texte
|
|
FROM rh.t_qualifications
|
|
WHERE 1=1
|
|
AND t_planning_qualification.qualification_id = t_qualifications.oid
|
|
AND (1!=1
|
|
OR qualification_code IS DISTINCT FROM t_qualifications.code
|
|
OR qualification_texte IS DISTINCT FROM t_qualifications.texte_court
|
|
OR qualification_section_id IS DISTINCT FROM t_qualifications.section_id
|
|
OR qualification_section_code IS DISTINCT FROM t_qualifications.section_code
|
|
OR qualification_section_texte IS DISTINCT FROM t_qualifications.section_texte)
|
|
;
|
|
|
|
-- Report des Services Paie sur Services Planning.
|
|
UPDATE rh.t_planning_service SET
|
|
service_code = t_services.code,
|
|
service_texte = t_services.texte_court,
|
|
service_section_id = t_services.section_id,
|
|
service_section_code = t_services.section_code,
|
|
service_section_texte = t_services.section_texte
|
|
FROM rh.t_services
|
|
WHERE 1=1
|
|
AND t_planning_service.service_id = t_services.oid
|
|
AND (1!=1
|
|
OR service_code IS DISTINCT FROM t_services.code
|
|
OR service_texte IS DISTINCT FROM t_services.texte_court
|
|
OR service_section_id IS DISTINCT FROM t_services.section_id
|
|
OR service_section_code IS DISTINCT FROM t_services.section_code
|
|
OR service_section_texte IS DISTINCT FROM t_services.section_texte)
|
|
;
|
|
|
|
-- Création des 3 classes de niveaux.
|
|
DROP TABLE IF EXISTS w_classes
|
|
;
|
|
|
|
CREATE TEMP TABLE w_classes AS
|
|
with classe_table as (
|
|
select 'PLANIV1' as code, '[DICT.RH.NIVEAU1#1]' as texte, 1 as sequence
|
|
UNION ALL
|
|
select 'PLANIV2' as code, '[DICT.RH.NIVEAU2#1]' as texte, 2 as sequence
|
|
UNION ALL
|
|
select 'PLANIV3' as code, '[DICT.RH.NIVEAU3#1]' as texte, 3 as sequence)
|
|
SELECT code, texte, table_id, 0 as is_cti, sequence
|
|
FROM classe_table, (select oid as table_id from rh.t_listes_tables where code = 'PNI' LIMIT 1) as subq
|
|
;
|
|
|
|
INSERT INTO rh.t_classes (code, texte, table_id, is_cti, sequence)
|
|
SELECT code, texte, table_id, is_cti, sequence
|
|
FROM w_classes
|
|
WHERE code NOT IN (SELECT code FROM rh.t_classes WHERE code is not null)
|
|
;
|
|
|
|
UPDATE rh.t_classes set
|
|
texte = w_classes.texte
|
|
FROM w_classes
|
|
WHERE true
|
|
and w_classes.code = t_classes.code
|
|
and w_classes.texte is distinct from t_classes.texte
|
|
;
|
|
|
|
-- Nettoyage du contenu
|
|
delete from rh.t_classes_sections_elements
|
|
where section_id in (
|
|
select s.oid from rh.t_classes as c
|
|
join rh.t_classes_sections as s on s.classe_id = c.oid
|
|
where c.code IN ('PLANIV1', 'PLANIV2', 'PLANIV3'))
|
|
;
|
|
|
|
-- Création des 3 classes de niveaux.
|
|
DROP TABLE IF EXISTS w_classes
|
|
;
|
|
|
|
CREATE TEMP TABLE w_classes AS
|
|
with classe_table as (
|
|
select 'PLANIV1' as code, '[DICT.RH.NIVEAU1#1]' as texte, 1 as sequence
|
|
UNION ALL
|
|
select 'PLANIV2' as code, '[DICT.RH.NIVEAU2#1]' as texte, 2 as sequence
|
|
UNION ALL
|
|
select 'PLANIV3' as code, '[DICT.RH.NIVEAU3#1]' as texte, 3 as sequence)
|
|
SELECT code, texte, table_id, 0 as is_cti, sequence
|
|
FROM classe_table, (select oid as table_id from rh.t_listes_tables where code = 'PNI' LIMIT 1) as subq
|
|
;
|
|
|
|
insert into rh.t_classes (code, texte, table_id, is_cti, sequence)
|
|
select code, texte, table_id, is_cti, sequence
|
|
FROM w_classes
|
|
where code NOT in (select code from rh.t_classes where code is not null)
|
|
;
|
|
|
|
update rh.t_classes set
|
|
texte = w_classes.texte
|
|
FROM w_classes
|
|
WHERE true
|
|
and w_classes.code = t_classes.code
|
|
and w_classes.texte is distinct from t_classes.texte
|
|
;
|
|
|
|
-- Nettoyage du contenu
|
|
delete from rh.t_classes_sections_elements
|
|
where section_id in (
|
|
select s.oid from rh.t_classes as c
|
|
join rh.t_classes_sections as s on s.classe_id = c.oid
|
|
where c.code IN ('PLANIV1', 'PLANIV2', 'PLANIV3'))
|
|
;
|
|
|
|
-- Mise à jour des sections Niveau 1.
|
|
DROP TABLE IF EXISTS w_clasec_1
|
|
;
|
|
|
|
-- avec soit la structure ayant le code établissements soit la structure racine
|
|
CREATE TEMP TABLE w_clasec_1 AS
|
|
SELECT
|
|
code,
|
|
nom as texte,
|
|
(select oid from rh.t_classes where code = 'PLANIV1') as classe_id
|
|
FROM prod_agiletime.structure
|
|
WHERE code = (SELECT planning_code FROM rh.t_etablissements WHERE planning_code != '')
|
|
GROUP BY 1,2,3
|
|
UNION ALL
|
|
SELECT
|
|
idstructure::text as code,
|
|
nom as texte,
|
|
(select oid from rh.t_classes where code = 'PLANIV1') as classe_id
|
|
FROM prod_agiletime.structure
|
|
WHERE idstructure = 1 AND (
|
|
SELECT
|
|
idstructure
|
|
FROM prod_agiletime.structure
|
|
WHERE code = (SELECT planning_code FROM rh.t_etablissements WHERE planning_code != '')
|
|
) IS NULL
|
|
GROUP BY 1,2,3
|
|
;
|
|
|
|
INSERT INTO rh.t_classes_sections(code, texte, classe_id)
|
|
SELECT code, texte, classe_id
|
|
from w_clasec_1
|
|
where 1=1
|
|
and classe_id = (select oid from rh.t_classes where code = 'PLANIV1')
|
|
and code not in (select code from rh.t_classes_sections where t_classes_sections.classe_id = w_clasec_1.classe_id and code is not null)
|
|
group by 1,2,3
|
|
;
|
|
|
|
UPDATE rh.t_classes_sections set
|
|
texte = w_clasec_1.texte
|
|
FROM w_clasec_1
|
|
WHERE true
|
|
AND w_clasec_1.classe_id = t_classes_sections.classe_id
|
|
AND w_clasec_1.code = t_classes_sections.code
|
|
AND w_clasec_1.texte is distinct from t_classes_sections.texte
|
|
;
|
|
|
|
-- Mise à jour du contenu des sections Niveau 1.
|
|
INSERT INTO rh.t_classes_sections_elements (section_id, to_id)
|
|
SELECT
|
|
t_classes_sections.oid AS section_id,
|
|
t_planning_niveau.oid AS to_id
|
|
FROM rh.t_classes
|
|
join rh.t_classes_sections on t_classes_sections.classe_id = t_classes.oid
|
|
join rh.t_planning_niveau on split_part(code_original, '|', 1) = t_classes_sections.code
|
|
WHERE t_classes.code = 'PLANIV1'
|
|
group by 1,2
|
|
;
|
|
|
|
-- Mise à jour des sections Niveau 2.
|
|
DROP TABLE IF EXISTS w_clasec_2
|
|
;
|
|
|
|
|
|
CREATE TEMP TABLE w_clasec_2 AS
|
|
SELECT
|
|
structure_code as code,
|
|
site_code || '|' || structure_code as code_original,
|
|
structure_nom as texte,
|
|
(select oid from rh.t_classes where code = 'PLANIV2') as classe_id
|
|
FROM w_structure
|
|
JOIN rh.t_divers ON code ='AGILETIME_NIV2' AND valeur = '1'
|
|
WHERE idstructure IS NOT NULL
|
|
GROUP BY 1,2,3
|
|
UNION ALL
|
|
SELECT
|
|
uepgroupe_code::text as code,
|
|
site_code || '|' || uepgroupe_code as code_original,
|
|
uepgroupe_nom as texte,
|
|
(select oid from rh.t_classes where code = 'PLANIV2') as classe_id
|
|
FROM w_structure
|
|
JOIN rh.t_divers ON code ='AGILETIME_NIV2' AND valeur = '0'
|
|
WHERE iduepgroupe IS NOT NULL
|
|
GROUP BY 1,2,3
|
|
UNION ALL
|
|
SELECT
|
|
site_code || '|' || 'NR',
|
|
site_code || '|' || 'NR',
|
|
'Non renseigné',
|
|
(select oid from rh.t_classes where code = 'PLANIV2') as classe_id
|
|
FROM
|
|
(SELECT DISTINCT site_code FROM w_structure) sub
|
|
;
|
|
|
|
INSERT INTO rh.t_classes_sections(code, texte, classe_id)
|
|
SELECT code, texte, classe_id
|
|
from w_clasec_2
|
|
where 1=1
|
|
and classe_id = (select oid from rh.t_classes where code = 'PLANIV2')
|
|
and code not in (select code from rh.t_classes_sections where t_classes_sections.classe_id = w_clasec_2.classe_id and code is not null)
|
|
group by 1,2,3
|
|
;
|
|
|
|
UPDATE rh.t_classes_sections set
|
|
texte = w_clasec_2.texte
|
|
FROM w_clasec_2
|
|
WHERE true
|
|
and w_clasec_2.classe_id = t_classes_sections.classe_id
|
|
and w_clasec_2.code = t_classes_sections.code
|
|
and w_clasec_2.texte is distinct from t_classes_sections.texte
|
|
;
|
|
|
|
-- Mise à jour du contenu des sections Niveau 2.
|
|
INSERT INTO rh.t_classes_sections_elements (section_id, to_id)
|
|
SELECT
|
|
t_classes_sections.oid AS section_id,
|
|
t_planning_niveau.oid AS to_id
|
|
FROM rh.t_classes
|
|
join rh.t_classes_sections on t_classes_sections.classe_id = t_classes.oid
|
|
join w_clasec_2 on true
|
|
and w_clasec_2.classe_id = t_classes.oid
|
|
and w_clasec_2.code = t_classes_sections.code
|
|
join rh.t_planning_niveau on split_part(t_planning_niveau.code_original, '|', 1)||'|'||split_part(t_planning_niveau.code_original, '|', 2) = w_clasec_2.code_original
|
|
WHERE t_classes.code = 'PLANIV2'
|
|
group by 1,2
|
|
;
|
|
|
|
-- Mise à jour des sections Niveau 3.
|
|
DROP TABLE IF EXISTS w_clasec_3
|
|
;
|
|
|
|
CREATE TEMP TABLE w_clasec_3 AS
|
|
SELECT
|
|
uep_code as code,
|
|
site_code || '|' || COALESCE(CASE WHEN valeur = 1 THEN structure_code ELSE uepgroupe_code END,'NR') || '|' || uep_code || CASE WHEN rank() OVER (PARTITION BY uep_code ORDER BY iduep) > 1 THEN '_2' ELSE '' END as code_original,
|
|
uep_nom as texte,
|
|
(select oid from rh.t_classes where code = 'PLANIV3') as classe_id
|
|
FROM w_structure
|
|
JOIN rh.t_divers ON code ='AGILETIME_NIV2'
|
|
;
|
|
|
|
INSERT INTO rh.t_classes_sections(code, texte, classe_id)
|
|
SELECT code, texte, classe_id
|
|
from w_clasec_3
|
|
where 1=1
|
|
and classe_id = (select oid from rh.t_classes where code = 'PLANIV3')
|
|
and code not in (select code from rh.t_classes_sections where t_classes_sections.classe_id = w_clasec_3.classe_id and code is not null)
|
|
group by 1,2,3
|
|
;
|
|
|
|
update rh.t_classes_sections set
|
|
texte = w_clasec_3.texte
|
|
FROM w_clasec_3
|
|
WHERE true
|
|
and w_clasec_3.classe_id = t_classes_sections.classe_id
|
|
and w_clasec_3.code = t_classes_sections.code
|
|
and w_clasec_3.texte is distinct from t_classes_sections.texte
|
|
;
|
|
|
|
-- Mise à jour du contenu des sections Niveau 3.
|
|
INSERT INTO rh.t_classes_sections_elements (section_id, to_id)
|
|
SELECT
|
|
t_classes_sections.oid AS section_id,
|
|
t_planning_niveau.oid AS to_id
|
|
FROM rh.t_classes
|
|
join rh.t_classes_sections on t_classes_sections.classe_id = t_classes.oid
|
|
join w_clasec_3 on true
|
|
and w_clasec_3.classe_id = t_classes.oid
|
|
and w_clasec_3.code = t_classes_sections.code
|
|
join rh.t_planning_niveau on split_part(t_planning_niveau.code_original, '|', 1)||'|'||split_part(t_planning_niveau.code_original, '|', 2)||'|'||split_part(t_planning_niveau.code_original, '|', 3) = w_clasec_3.code_original
|
|
WHERE t_classes.code = 'PLANIV3'
|
|
group by 1,2
|
|
;
|
|
|
|
SELECT rh.cti_update_schema_classes('*ALL')
|
|
;
|
|
|
|
-- Recensement des oid utilisés.
|
|
INSERT INTO rh.p_oids (code_table, oid)
|
|
SELECT 'planning_service', service_id
|
|
FROM rh.p_planning_mouvement
|
|
WHERE service_id NOT IN (SELECT oid FROM rh.p_oids WHERE code_table = 'planning_service')
|
|
GROUP BY 1,2
|
|
;
|
|
|
|
INSERT INTO rh.p_oids (code_table, oid)
|
|
SELECT 'planning_qualification', qualification_id
|
|
FROM rh.p_planning_mouvement
|
|
WHERE qualification_id NOT IN (SELECT oid FROM rh.p_oids WHERE code_table = 'planning_qualification')
|
|
GROUP BY 1,2
|
|
;
|
|
|
|
INSERT INTO rh.p_oids (code_table, oid)
|
|
SELECT 'planning_niveau', niveau_id
|
|
FROM rh.p_planning_mouvement
|
|
WHERE niveau_id NOT IN (SELECT oid FROM rh.p_oids WHERE code_table = 'planning_niveau')
|
|
GROUP BY 1,2
|
|
;
|
|
|
|
INSERT INTO rh.p_oids (code_table, oid)
|
|
SELECT 'planning_type_absence', type_absence_id
|
|
FROM rh.p_planning_mouvement
|
|
WHERE type_absence_id NOT IN (SELECT oid FROM rh.p_oids WHERE code_table = 'planning_type_absence')
|
|
GROUP BY 1,2
|
|
;
|
|
|
|
]]></sqlcmd>
|
|
</NODE>
|
|
</ROOT>
|