<?xml version="1.0" encoding="ISO-8859-1"?>
|
|
<ROOT>
|
|
<NODE name="INIT" type="common" />
|
|
<NODE name="PROD" label="Synchronisation données">
|
|
<NODE label="Import planning">
|
|
<sqlcmd><![CDATA[
|
|
|
|
-- Màj des Etablissements
|
|
-- UPDATE rh.t_etablissements
|
|
-- SET planning_code = code
|
|
-- ;
|
|
|
|
-- /!\ planning_code est à paramétrer dans la table listant les établissements.
|
|
|
|
-- 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
|
|
-- Uniquement les établissements avec planning_code renseigné dans le cas où l'établissement est en mode manuel.
|
|
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
|
|
;
|
|
|
|
-- #CORRECTION SHS lorsque le code établissement contient un tiret, utiliser son code original uniquement pour matricule_planning.
|
|
UPDATE w_sal_pla SET
|
|
matricule_planning = etablissement_code_original || matricule
|
|
WHERE etablissement_code LIKE '%-%'
|
|
;
|
|
|
|
-- 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_gntyphsp
|
|
;
|
|
CREATE TEMP TABLE w_gntyphsp AS
|
|
SELECT
|
|
typhsp_cumh = 0 AND typhsp_cump = 1 AND typhsp_fact = 0 as est_absence, -- absence (pas de cumul temps_valide mais temps_du)
|
|
-- rub_id = 0 AND typhsp_cumh = 0 AS est_h_planif_sup_back, -- pas de cumul temps_valide
|
|
(rub_id = 0 OR typhsp_spla = 0) AND typhsp_cumh = 0 AND typhsp_cump = 1 and typhsp_fact = 0 AS est_h_planif_sup, -- pas de cumul temps_valide mais planning
|
|
rub_id != 0 AND typhsp_cump = 0 and typhsp_fact = 0 AS est_h_planif_moins, -- pas de cumul temps_valide mais moins planning
|
|
CASE WHEN rub_id != 0 AND typhsp_chvh = 1 AND typhsp_cumh = 1 THEN true ELSE false END AS est_h_planif_sup_at, -- cumul heures pour Ast travaillée
|
|
rub_id IS NULL
|
|
OR (rub_id != 0 AND NOT ((typhsp_chvh > 0 and typhsp_cumh = 0) OR (typhsp_spla = 1 AND TYPHSP_SCOR = 1 AND typhsp_cump =0 AND typhsp_cumh =0 )))
|
|
OR (rub_id = 0) AS est_comptabilise, -- hors Ast non travaillée et heure non comptab en heures ou planning (dépendant de REU peut être réduit à la deuxième condition)
|
|
GNTYPHSP.*
|
|
FROM prod_cegi.gntyphsp
|
|
ORDER by typhsp_code
|
|
;
|
|
|
|
DROP TABLE IF EXISTS w_corct
|
|
;
|
|
CREATE TEMP TABLE w_corct AS
|
|
SELECT 'AR' as code, -1.0 as signe, 0.0 as surcharge -- Arrivée en retard.
|
|
UNION ALL
|
|
SELECT 'AV' as code, 1.0 as signe, 0.0 as surcharge -- Arrivée en avance.
|
|
UNION ALL
|
|
SELECT 'AW' as code, 1.0 as signe, 0.0 as surcharge -- Astreinte travaillée.
|
|
UNION ALL
|
|
SELECT 'DA' as code, -1.0 as signe, 0.0 as surcharge -- Départ en avance.
|
|
UNION ALL
|
|
SELECT 'DR' as code, 1.0 as signe, 0.0 as surcharge -- Départ en retard.
|
|
UNION ALL
|
|
SELECT 'M1' as code, 1.0 as signe, 1.0 as surcharge -- Modification complète type 1.
|
|
UNION ALL
|
|
SELECT 'M2' as code, 1.0 as signe, 1.0 as surcharge -- Modification complète type 2.
|
|
UNION ALL
|
|
SELECT 'OAW' as code, 1.0 as signe, 0.0 as surcharge -- Astreinte travaillée.
|
|
;
|
|
|
|
DROP TABLE IF EXISTS w_structure
|
|
;
|
|
CREATE TEMP TABLE w_structure AS
|
|
SELECT
|
|
GNEQP.site_id,
|
|
eqp_id,
|
|
planning_code,
|
|
CASE WHEN COALESCE(cegi_site_service.valeur,'0') = '0' THEN
|
|
site_code || '|' || COALESCE(GNTYPEQP.typeqp_code,'NR') || '|' || eqp_code
|
|
ELSE planning_code || '|' || site_code || '|' || eqp_code
|
|
END AS code,
|
|
MAX(CASE WHEN COALESCE(cegi_site_service.valeur,'0') = '0' THEN
|
|
site_lib || '|' || CASE WHEN typeqp_lib IS NOT NULL THEN ' - ' || COALESCE(typeqp_lib,' ') ELSE '' END || '-' || eqp_lib
|
|
ELSE t_etablissements.texte || '-' || site_lib || '|' || eqp_lib
|
|
END) AS texte
|
|
FROM
|
|
prod_cegi.GNEQP
|
|
LEFT JOIN prod_cegi.GNTYPEQP ON GNEQP.typeqp_code = GNTYPEQP.typeqp_code
|
|
LEFT JOIN (SELECT valeur FROM rh.t_divers WHERE code = 'CEGI_SITE_SERVICE') AS cegi_site_service ON 1=1
|
|
JOIN prod_cegi.GNSITE on GNSITE.site_id = GNEQP.site_id
|
|
JOIN rh.t_etablissements ON t_etablissements.planning_code = CASE WHEN COALESCE(cegi_site_service.valeur,'0') = '0' THEN site_code ELSE planning_code END
|
|
WHERE planning_code != '*'
|
|
GROUP BY 1,2,3,4
|
|
;
|
|
|
|
DROP TABLE IF EXISTS w_gnpla
|
|
;
|
|
CREATE TEMP TABLE w_gnpla AS
|
|
WITH planning_override AS (
|
|
SELECT
|
|
per_id,
|
|
pla_date,
|
|
pla_ordre
|
|
FROM prod_cegi.GNPLADC
|
|
WHERE GNPLADC.pladc_ordre = 0
|
|
GROUP BY 1,2,3
|
|
)
|
|
, ar_da as ( -- Calcul des temps en +/-.
|
|
SELECT
|
|
per_id,
|
|
pla_date,
|
|
pla_ordre,
|
|
sum(pladc_duree * signe) as pladc_duree
|
|
FROM prod_cegi.GNPLADC
|
|
join w_corct on w_corct.code = GNPLADC.corct_code
|
|
WHERE corct_code in ('AR', 'AV', 'DA', 'DR')
|
|
GROUP BY 1,2,3
|
|
)
|
|
SELECT
|
|
gnpla.pla_type,
|
|
gnpla.pla_date,
|
|
gnpla.pla_heud,
|
|
gnpla.pla_heuf,
|
|
gnpla.SER_CODE,
|
|
0::numeric as pla_duree,
|
|
coalesce(
|
|
case when (CASE WHEN gnpla.pla_heuf > gnpla.pla_heud THEN (gnpla.pla_heuf - gnpla.pla_heud) ELSE ('1899-12-30 24:00:00' - gnpla.pla_heud) + (gnpla.pla_heuf - '1899-12-30 00:00:00') END)
|
|
+ (coalesce(ar_da.pladc_duree, 0)::text || ' minutes')::interval < '6 hours'::interval
|
|
then 0.0 -- #HINT02 Les pauses ne doivent pas être décomptées lorsque le temps de travail est < 6h (légal).
|
|
else
|
|
case when coalesce(typhsp_plapause, ''::text) in (select unnest(string_to_array(replace(valeur, ' ', ''), ',')) from rh.t_divers where code = 'CEGI_PAUSE_EXCL') -- #HINT03 Les pauses payées ne doivent pas être décomptées du temps travaillées (ex : sandwitch mangé tout en restant à l'accueil le dimanche).
|
|
then 0.0
|
|
else gnpla.pla_pause
|
|
end
|
|
end,
|
|
gnpla.pla_pause
|
|
) as pla_pause,
|
|
gnpla.prs_code,
|
|
gnpla.typhsp_code,
|
|
--GNPLA.*,
|
|
salarie_id,
|
|
sal_matricule,
|
|
sal_matricule AS salarie_corr,
|
|
cnt_id,
|
|
COALESCE(est_absence,false) AS est_absence,
|
|
COALESCE(est_h_planif_sup,false) AS est_h_planif_sup,
|
|
COALESCE(est_h_planif_moins,false) AS est_h_planif_moins,
|
|
w_structure.planning_code,
|
|
w_structure.code,
|
|
w_structure.texte,
|
|
w_structure.code AS code_original
|
|
FROM prod_cegi.GNPLA
|
|
JOIN prod_cegi.PYSALARIE ON GNPLA.per_id = PYSALARIE.per_id
|
|
left JOIN planning_override ON 1=1
|
|
AND planning_override.per_id = GNPLA.per_id
|
|
AND planning_override.pla_date = GNPLA.pla_date
|
|
AND planning_override.pla_ordre = GNPLA.pla_ordre
|
|
left JOIN ar_da ON 1=1
|
|
AND ar_da.per_id = GNPLA.per_id
|
|
AND ar_da.pla_date = GNPLA.pla_date
|
|
AND ar_da.pla_ordre = GNPLA.pla_ordre
|
|
JOIN w_structure ON GNPLA.eqp_id = w_structure.eqp_id AND GNPLA.site_id = w_structure.site_id
|
|
LEFT JOIN w_gntyphsp ON GNPLA.typhsp_code = w_gntyphsp.typhsp_code
|
|
LEFT JOIN (SELECT valeur FROM rh.t_divers WHERE code = 'CEGI_SITE_SERVICE') AS cegi_site_service ON 1=1
|
|
JOIN w_sal_pla ON w_sal_pla.salarie_corr = sal_matricule AND etablissement_planning_code = planning_code
|
|
WHERE 1=1
|
|
AND planning_override.per_id IS NULL
|
|
AND (1!=1
|
|
OR pla_heuf < pla_heud
|
|
OR EXTRACT(epoch from (pla_heuf - pla_heud) - (pla_pause::text || ' minutes')::interval) > 60) -- les mouvements d'une minute sont destinés à la paoe
|
|
AND (1!=1
|
|
OR est_comptabilise IS NULL
|
|
OR est_comptabilise)
|
|
;
|
|
|
|
DROP TABLE IF EXISTS w_gnpladc
|
|
;
|
|
CREATE TEMP TABLE w_gnpladc AS
|
|
SELECT
|
|
pla_type,
|
|
gnpladc.pla_date,
|
|
case
|
|
when GNPLADC.corct_code = 'AW' then pla_heud -- #HINT01 Recalcul de la borne de fin lorsque motif Astreinte Travaillées (AW) car elle ne sont pas forcément renseignées ou mal (cas astreinte travaillée fragmentée) --> recalcul de la borne de fin à partir de la durée qui elle est juste.
|
|
else pladc_heudeb
|
|
end as pladc_heudeb,
|
|
case
|
|
when GNPLADC.corct_code = 'AW' then pla_heud + (pladc_duree::text || ' minutes')::interval -- cf. #HINT01.
|
|
else pladc_heufin
|
|
end as pladc_heufin,
|
|
pla_heud,
|
|
pla_heuf,
|
|
pladc_duree as pladc_duree,
|
|
gnpla.pla_pause AS pla_pause,
|
|
prs_code,
|
|
SER_CODE,
|
|
gnpladc.typhsp_code,
|
|
GNPLADC.corct_code,
|
|
salarie_id,
|
|
sal_matricule,
|
|
sal_matricule AS salarie_corr,
|
|
cnt_id,
|
|
COALESCE(est_absence, false) AS est_absence,
|
|
COALESCE(est_h_planif_sup_at,false) AS est_h_planif_sup_at,
|
|
CASE WHEN est_absence AND pladc_heudeb BETWEEN pla_heud AND pla_heuf THEN true ELSE false END AS est_h_planif_sup_absence,
|
|
w_structure.planning_code,
|
|
w_structure.code,
|
|
w_structure.texte,
|
|
w_structure.code AS code_original
|
|
FROM prod_cegi.GNPLADC
|
|
JOIN prod_cegi.GNPLA ON GNPLA.per_id = GNPLADC.per_id AND GNPLA.pla_date = GNPLADC.pla_date AND GNPLA.pla_ordre = GNPLADC.pla_ordre AND pla_type = 0
|
|
JOIN prod_cegi.PYSALARIE ON GNPLA.per_id = PYSALARIE.per_id
|
|
JOIN w_structure ON GNPLA.eqp_id = w_structure.eqp_id AND GNPLA.site_id = w_structure.site_id
|
|
LEFT JOIN w_gntyphsp ON GNPLADC.typhsp_code = w_gntyphsp.typhsp_code
|
|
JOIN w_sal_pla ON w_sal_pla.salarie_corr = sal_matricule AND etablissement_planning_code = planning_code
|
|
WHERE
|
|
(est_comptabilise IS NULL OR est_comptabilise)
|
|
;
|
|
|
|
|
|
|
|
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,
|
|
w_gnpla.salarie_corr,
|
|
salarie_id,
|
|
cnt_id,
|
|
null::bigint AS contrat_id,
|
|
null::bigint AS contrat_mois_id,
|
|
date(pla_date) AS date,
|
|
date(pla_date) AS date_orig,
|
|
EXTRACT(epoch FROM CASE WHEN pla_heuf > pla_heud THEN (pla_heuf - pla_heud) - (pla_pause::text || ' minutes')::interval ELSE (pla_heuf + interval '1 day' - pla_heud) - (pla_pause::text || ' minutes')::interval END)/3600 AS temps_orig,
|
|
prs_code,
|
|
code_original AS niveau_code_original,
|
|
code_original AS service_code_original,
|
|
planning_code AS entets_code,
|
|
SER_CODE::text,
|
|
typhsp_code AS type_horaire,
|
|
CASE WHEN est_absence AND NOT est_h_planif_sup THEN typhsp_code ELSE ''::text END AS abs_cod,
|
|
0::numeric AS temps_du_initial,
|
|
CASE WHEN est_h_planif_sup THEN EXTRACT(epoch FROM CASE WHEN pla_heuf > pla_heud THEN (pla_heuf - pla_heud) - (pla_pause::text || ' minutes')::interval ELSE ('1899-12-30 24:00:00' - pla_heud) - (pla_pause::text || ' minutes')::interval END)/3600
|
|
WHEN est_h_planif_moins THEN -EXTRACT(epoch FROM CASE WHEN pla_heuf > pla_heud THEN (pla_heuf - pla_heud) - (pla_pause::text || ' minutes')::interval ELSE ('1899-12-30 24:00:00' - pla_heud) - (pla_pause::text || ' minutes')::interval END)/3600
|
|
ELSE 0:: numeric END AS temps_du,
|
|
CASE WHEN NOT est_absence THEN EXTRACT(epoch FROM CASE WHEN pla_heuf > pla_heud THEN (pla_heuf - pla_heud) - (pla_pause::text || ' minutes')::interval ELSE ('1899-12-30 24:00:00' - pla_heud) - (pla_pause::text || ' minutes')::interval END)/3600 ELSE 0:: numeric END AS temps_valide,
|
|
CASE WHEN est_absence AND NOT est_h_planif_sup THEN EXTRACT(epoch FROM CASE WHEN pla_heuf > pla_heud THEN (pla_heuf - pla_heud) - (pla_pause::text || ' minutes')::interval ELSE ('1899-12-30 24:00:00' - pla_heud) - (pla_pause::text || ' minutes')::interval END)/3600 ELSE 0:: numeric END AS temps_absence
|
|
FROM w_gnpla
|
|
WHERE 1=1
|
|
AND pla_type = 0 -- effectué
|
|
AND EXTRACT(epoch FROM (pla_heuf - pla_heud) - (pla_pause::text || ' minutes')::interval) != 0 -- pour la paie
|
|
ORDER BY 2,7
|
|
;
|
|
|
|
INSERT INTO w_cptres1
|
|
SELECT
|
|
nextval('w_cptres1_seq') as cptres1_id,
|
|
w_gnpla.salarie_corr,
|
|
salarie_id,
|
|
cnt_id,
|
|
null::bigint AS contrat_id,
|
|
null::bigint AS contrat_mois_id,
|
|
date(pla_date) + interval '1 day' AS date,
|
|
date(pla_date) AS date_orig,
|
|
EXTRACT(epoch FROM CASE WHEN pla_heuf > pla_heud THEN (pla_heuf - pla_heud) ELSE (pla_heuf + interval '1 day' - pla_heud) END)/3600 AS temps_orig,
|
|
prs_code,
|
|
code_original AS niveau_code_original,
|
|
code_original AS service_code_original,
|
|
planning_code AS entets_code,
|
|
SER_CODE,
|
|
typhsp_code AS type_horaire,
|
|
CASE WHEN est_absence AND NOT est_h_planif_sup THEN typhsp_code ELSE ''::text END AS abs_cod,
|
|
0 AS temps_du_initial,
|
|
CASE WHEN est_h_planif_sup THEN EXTRACT(epoch FROM (pla_heuf - '1899-12-30 00:00:00'))/3600
|
|
WHEN est_h_planif_moins THEN -EXTRACT(epoch FROM (pla_heuf - '1899-12-30 00:00:00'))/3600
|
|
ELSE 0::numeric END AS temps_du,
|
|
CASE WHEN NOT est_absence THEN EXTRACT(epoch FROM (pla_heuf - '1899-12-30 00:00:00'))/3600 ELSE 0::numeric END AS temps_valide,
|
|
CASE WHEN est_absence AND NOT est_h_planif_sup THEN EXTRACT(epoch FROM (pla_heuf - '1899-12-30 00:00:00'))/3600 ELSE 0::numeric END AS temps_absence
|
|
FROM w_gnpla
|
|
WHERE 1=1
|
|
AND pla_type = 0 -- effectué
|
|
--AND NOT est_absence
|
|
--AND NOT est_h_planif_sup
|
|
AND (EXTRACT(epoch FROM (pla_heuf - pla_heud) - (pla_pause::text || ' minutes')::interval) < 0 OR pla_duree > 1440)-- journée dépassant les minuit
|
|
AND EXTRACT(epoch FROM (pla_heuf - pla_heud) - (pla_pause::text || ' minutes')::interval) != 0 -- pour la paie
|
|
ORDER BY 2,7
|
|
;
|
|
-- heures travaillees supplémentaires
|
|
|
|
INSERT INTO w_cptres1
|
|
SELECT
|
|
nextval('w_cptres1_seq') as cptres1_id,
|
|
w_gnpladc.salarie_corr,
|
|
salarie_id,
|
|
cnt_id,
|
|
null::bigint AS contrat_id,
|
|
null::bigint AS contrat_mois_id,
|
|
date(pla_date) AS date,
|
|
date(pla_date) AS date_orig,
|
|
SUM(CASE WHEN NOT est_absence THEN pladc_duree/60.0 ELSE -pladc_duree/60.0 END)AS temps_orig,
|
|
prs_code,
|
|
code_original AS niveau_code_original,
|
|
code_original AS service_code_original,
|
|
planning_code AS entets_code,
|
|
SER_CODE,
|
|
typhsp_code AS type_horaire,
|
|
''::text AS abs_cod,
|
|
0::numeric AS temps_du_initial,
|
|
SUM(CASE
|
|
WHEN est_h_planif_sup_at THEN -EXTRACT(epoch FROM CASE WHEN pladc_heufin > pladc_heudeb OR pladc_duree > 1440 THEN (pladc_heufin - pladc_heudeb) ELSE ('1899-12-30 24:00:00' - pladc_heudeb) END)/3600::numeric
|
|
WHEN est_h_planif_sup_absence THEN EXTRACT(epoch FROM CASE WHEN pladc_heufin > pladc_heudeb OR pladc_duree > 1440 THEN (pladc_heufin - pladc_heudeb) ELSE ('1899-12-30 24:00:00' - pladc_heudeb) END)/3600::numeric
|
|
ELSE 0::numeric
|
|
END * coalesce(w_corct.signe, 1.0)) AS temps_du,
|
|
SUM(CASE WHEN NOT est_absence
|
|
THEN EXTRACT(epoch FROM CASE WHEN pladc_heufin > pladc_heudeb OR pladc_duree > 1440 THEN (pladc_heufin - pladc_heudeb) ELSE ('1899-12-30 24:00:00' - pladc_heudeb) END)/3600 - ((pla_pause / 60.0) * coalesce(w_corct.surcharge, 0.0))-- Les pauses ne sont retirées qu'une fois sur le jour 1 lorsque code de modification M1/M2.
|
|
ELSE -EXTRACT(epoch FROM CASE WHEN pladc_heufin > pladc_heudeb OR pladc_duree > 1440 THEN (pladc_heufin - pladc_heudeb) ELSE ('1899-12-30 24:00:00' - pladc_heudeb) END)/3600
|
|
END * coalesce(w_corct.signe, 1.0)) AS temps_valide,
|
|
0::numeric AS temps_absence
|
|
FROM w_gnpladc
|
|
left join w_corct on w_corct.code = w_gnpladc.corct_code
|
|
WHERE 1=1
|
|
GROUP BY 1,2,3,4,5,6,7,8,10,11,12,13,14,15,16,17
|
|
ORDER BY 2,7
|
|
;
|
|
|
|
-- Traitement du deuxième jour lorsqu'évènement salarié chevauchant 2 jours.
|
|
INSERT INTO w_cptres1
|
|
SELECT
|
|
nextval('w_cptres1_seq') as cptres1_id,
|
|
w_gnpladc.salarie_corr,
|
|
salarie_id,
|
|
cnt_id,
|
|
null::bigint AS contrat_id,
|
|
null::bigint AS contrat_mois_id,
|
|
date(pla_date) + interval '1 day' AS date,
|
|
date(pla_date) AS date_orig,
|
|
SUM(CASE WHEN est_absence THEN pladc_duree/60.0 ELSE -pladc_duree/60.0 END)AS temps_orig,
|
|
prs_code,
|
|
code_original AS niveau_code_original,
|
|
code_original AS service_code_original,
|
|
planning_code AS entets_code,
|
|
SER_CODE,
|
|
typhsp_code AS type_horaire,
|
|
''::text AS abs_cod,
|
|
0 AS temps_du_initial,
|
|
SUM(
|
|
CASE WHEN est_h_planif_sup_at THEN
|
|
-EXTRACT(epoch FROM (pladc_heufin - '1899-12-30 00:00:00'))/3600
|
|
WHEN est_h_planif_sup_absence THEN
|
|
EXTRACT(epoch FROM (pladc_heufin - '1899-12-30 00:00:00'))/3600
|
|
ELSE
|
|
0 END
|
|
* coalesce(w_corct.signe, 1.0)) AS temps_du,
|
|
SUM(CASE WHEN NOT est_absence THEN
|
|
EXTRACT(epoch FROM (pladc_heufin - '1899-12-30 00:00:00'))/3600
|
|
ELSE
|
|
-EXTRACT(epoch FROM (pladc_heufin - '1899-12-30 00:00:00'))/3600
|
|
END * coalesce(w_corct.signe, 1.0)) AS temps_valide,
|
|
0::numeric AS temps_absence
|
|
FROM w_gnpladc
|
|
left join w_corct on w_corct.code = w_gnpladc.corct_code
|
|
WHERE 1=1
|
|
AND EXTRACT(epoch FROM (pladc_heufin - pladc_heudeb)) < 0 OR pladc_duree > 1440 -- journée dépassant les minuit
|
|
GROUP BY 1,2,3,4,5,6,7,8,10,11,12,13,14,15,16,17
|
|
ORDER BY 2,7
|
|
;
|
|
|
|
|
|
-- heures planifiées
|
|
INSERT INTO w_cptres1
|
|
SELECT
|
|
nextval('w_cptres1_seq') as cptres1_id,
|
|
w_gnpla.salarie_corr,
|
|
salarie_id,
|
|
cnt_id,
|
|
null::bigint AS contrat_id,
|
|
null::bigint AS contrat_mois_id,
|
|
date(pla_date) AS date,
|
|
date(pla_date) AS date_orig,
|
|
EXTRACT(epoch FROM CASE WHEN pla_heuf > pla_heud THEN (pla_heuf - pla_heud) - (pla_pause::text || ' minutes')::interval ELSE (pla_heuf + interval '1 day' - pla_heud) - (pla_pause::text || ' minutes')::interval END)/3600 AS temps_orig,
|
|
prs_code,
|
|
code_original AS niveau_code_original,
|
|
code_original AS service_code_original,
|
|
planning_code AS entets_code,
|
|
SER_CODE,
|
|
typhsp_code AS type_horaire,
|
|
''::text AS abs_cod,
|
|
EXTRACT(epoch FROM CASE WHEN pla_heuf > pla_heud THEN (pla_heuf - pla_heud) - (pla_pause::text || ' minutes')::interval ELSE ('1899-12-30 24:00:00' - pla_heud) - (pla_pause::text || ' minutes')::interval END)/3600 AS temps_du_initial,
|
|
0 AS temps_du,
|
|
0 AS temps_valide,
|
|
0::numeric AS temps_absence
|
|
FROM w_gnpla
|
|
WHERE 1=1
|
|
AND pla_type = 1 -- planifié prev
|
|
AND NOT est_absence
|
|
AND EXTRACT(epoch FROM (pla_heuf - pla_heud) - (pla_pause::text || ' minutes')::interval) != 0 -- pour la paie
|
|
ORDER BY 2,7
|
|
;
|
|
|
|
INSERT INTO w_cptres1
|
|
SELECT
|
|
nextval('w_cptres1_seq') as cptres1_id,
|
|
w_gnpla.salarie_corr,
|
|
salarie_id,
|
|
cnt_id,
|
|
null::bigint AS contrat_id,
|
|
null::bigint AS contrat_mois_id,
|
|
date(pla_date + interval '1 day') AS date,
|
|
date(pla_date) AS date_orig,
|
|
EXTRACT(epoch FROM CASE WHEN pla_heuf > pla_heud THEN (pla_heuf - pla_heud) - (pla_pause::text || ' minutes')::interval ELSE (pla_heuf + interval '1 day' - pla_heud) - (pla_pause::text || ' minutes')::interval END)/3600 AS temps_orig,
|
|
prs_code,
|
|
code_original AS niveau_code_original,
|
|
code_original AS service_code_original,
|
|
planning_code AS entets_code,
|
|
SER_CODE,
|
|
typhsp_code AS type_horaire,
|
|
''::text AS abs_cod,
|
|
EXTRACT(epoch FROM (pla_heuf - '1899-12-30 00:00:00'))/3600 AS temps_du_initial,
|
|
0 AS temps_du,
|
|
0 AS temps_valide,
|
|
0::numeric AS temps_absence
|
|
FROM w_gnpla
|
|
WHERE 1=1
|
|
AND pla_type = 1 -- planifié prev
|
|
AND NOT est_absence
|
|
AND EXTRACT(epoch FROM (pla_heuf - pla_heud) - (pla_pause::text || ' minutes')::interval) < 0 -- journée dépassant les minuit
|
|
AND EXTRACT(epoch FROM (pla_heuf - pla_heud) - (pla_pause::text || ' minutes')::interval) != 0 -- pour la paie
|
|
ORDER BY 2,7
|
|
;
|
|
|
|
-- Code d'absence paramétrés en heure
|
|
DROP TABLE IF EXISTS w_codes_absences_unite_heure
|
|
;
|
|
|
|
CREATE TEMP TABLE w_codes_absences_unite_heure AS
|
|
SELECT abspar_code
|
|
FROM prod_cegi.PYABSENCEPARAM
|
|
WHERE
|
|
(
|
|
un_id IN (708, 709 ,710, 711)
|
|
OR un_id IN (SELECT UNNEST(STRING_TO_ARRAY(REPLACE(valeur, ' ', ''), ',')) FROM rh.t_divers WHERE code = 'CEGI_UNITE_HEURE') -- Absences paramétrées dans CTI comme étant exprimées en heures.
|
|
)
|
|
AND abspar_code NOT IN (SELECT UNNEST(STRING_TO_ARRAY(REPLACE(valeur, ' ', ''), ',')) FROM rh.t_divers WHERE code = 'CEGI_PLANNING_ABSENCE_HEURE')
|
|
ORDER BY abspar_code
|
|
;
|
|
|
|
-- Modulation des présence avec les absences
|
|
-- Recencement des absences exprimées en jours et en heures.
|
|
DROP TABLE IF EXISTS w_abs_bul
|
|
;
|
|
CREATE TEMP TABLE w_abs_bul AS
|
|
SELECT
|
|
pyabsence.per_id,
|
|
cnt_id,
|
|
sal_matricule,
|
|
detabs_deb as dphl_debabs,
|
|
detabs_fin as dphl_finabs,
|
|
sum(detabs_val) as dphl_valabs,
|
|
abspar_code as dphl_code,
|
|
abspar_libelle as dphl_lib,
|
|
un_id
|
|
FROM prod_cegi.PYABSENCE
|
|
JOIN prod_cegi.PYDETABSENCE ON PYABSENCE.abs_id = PYDETABSENCE.abs_id
|
|
JOIN prod_cegi.PYSALARIE ON PYABSENCE.per_id = PYSALARIE.per_id
|
|
JOIN prod_cegi.PYABSENCEPARAM ON PYABSENCEPARAM.abspar_id = PYABSENCE.abspar_id
|
|
WHERE 1=1
|
|
AND CASE WHEN (select valeur = '1' from rh.t_divers where code = 'CEGI_ABS_VALIDE') THEN abs_valide = 1 ELSE true END
|
|
AND abspar_code not in (select unnest(string_to_array(replace(valeur, ' ', ''), ',')) from rh.t_divers where code = 'CEGI_ABS_EXCL')
|
|
AND detabs_val IS NOT NULL
|
|
GROUP BY 1,2,3,4,5,7,8,9
|
|
;
|
|
|
|
-- CAS des absence en jours : on transvase l'intégralité du temps validé dans le temps d'absence et on met le temps validé à 0.
|
|
UPDATE w_cptres1
|
|
SET
|
|
abs_cod = dphl_code,
|
|
temps_absence = temps_valide,
|
|
temps_valide = 0
|
|
FROM
|
|
w_abs_bul
|
|
WHERE 1=1
|
|
AND w_abs_bul.sal_matricule = salarie_corr
|
|
AND date_orig BETWEEN dphl_debabs AND dphl_finabs
|
|
AND dphl_code NOT IN (SELECT abspar_code FROM w_codes_absences_unite_heure) -- Hors absences exprimées en heures.
|
|
AND temps_valide != 0
|
|
;
|
|
|
|
-- Table temporaire qui va permettre de décompter les heures d'absences étalées sur plusieurs jours.
|
|
DROP TABLE IF EXISTS w_abs_h
|
|
;
|
|
CREATE TEMP TABLE w_abs_h AS
|
|
SELECT
|
|
w_cptres1.*,
|
|
dphl_code,
|
|
dphl_lib,
|
|
dphl_valabs,
|
|
SUM(temps_valide) OVER (PARTITION BY salarie_corr, w_abs_bul.cnt_id, dphl_debabs, dphl_code ORDER by date_orig, date, cptres1_id) as somme,
|
|
dphl_valabs + temps_valide - SUM(temps_valide) OVER (PARTITION BY salarie_corr, w_abs_bul.cnt_id, dphl_debabs, dphl_code ORDER by date_orig, date, cptres1_id) as restant
|
|
FROM w_abs_bul
|
|
JOIN w_cptres1 ON w_abs_bul.sal_matricule = salarie_corr and w_abs_bul.cnt_id = w_cptres1.cnt_id
|
|
AND date_orig BETWEEN dphl_debabs AND dphl_finabs
|
|
WHERE 1=1
|
|
AND dphl_code IN (SELECT abspar_code FROM w_codes_absences_unite_heure) -- Hors absences exprimées en heures.
|
|
;
|
|
|
|
-- Absences en heures
|
|
UPDATE w_cptres1 SET
|
|
temps_valide = w_cptres1.temps_valide - LEAST(w_cptres1.temps_valide, restant)
|
|
FROM
|
|
(SELECT
|
|
salarie_corr,
|
|
cnt_id,
|
|
date_orig,
|
|
sum(restant) as restant
|
|
FROM
|
|
w_abs_h
|
|
WHERE restant > 0 -- a deplacer vers la creation
|
|
GROUP BY 1,2,3
|
|
) as w_abs_h_group
|
|
WHERE
|
|
w_cptres1.salarie_corr = w_abs_h_group.salarie_corr AND
|
|
w_cptres1.cnt_id = w_abs_h_group.cnt_id AND
|
|
w_cptres1.date_orig = w_abs_h_group.date_orig AND
|
|
--w_cptres1.date = w_abs_h.date AND
|
|
w_cptres1.temps_valide > 0
|
|
;
|
|
|
|
--todo ajouter cas eventuel non present d'absences longue mais ne constituant pas un nombre de jours exactes
|
|
INSERT INTO w_cptres1
|
|
SELECT
|
|
nextval('w_cptres1_seq') as cptres1_id,
|
|
salarie_corr,
|
|
salarie_id,
|
|
cnt_id,
|
|
null::bigint AS contrat_id,
|
|
null::bigint AS contrat_mois_id,
|
|
date,
|
|
date_orig,
|
|
0 as temps_orig,
|
|
prs_code,
|
|
niveau_code_original,
|
|
service_code_original,
|
|
entets_code,
|
|
SER_CODE,
|
|
''::text AS type_horaire,
|
|
dphl_code AS abs_cod,
|
|
0 AS temps_du_initial,
|
|
0 AS temps_du,
|
|
0 AS temps_valide,
|
|
LEAST(temps_valide,restant) AS temps_absence --bug observé sur cette rubrique
|
|
FROM w_abs_h
|
|
WHERE
|
|
dphl_valabs != 0
|
|
and restant > 0
|
|
|
|
;
|
|
|
|
|
|
|
|
|
|
--correctif rrh et amith qui s'ils sont seuls prennet la valeur travaillée même si leur valeur d'absence ne couvre pas la journée
|
|
DROP TABLE IF EXISTS w_tot_absence;
|
|
CREATE TEMP TABLE w_tot_absence AS
|
|
SELECT
|
|
salarie_corr,
|
|
date_orig,
|
|
CASE
|
|
WHEN 'AMITH' = ANY(array_agg(abs_cod)) THEN 'AMITH'
|
|
WHEN 'RRH' = ANY(array_agg(abs_cod)) THEN 'RRH'
|
|
END AS code,
|
|
sum(temps_absence) as tot_absence
|
|
FROM w_cptres1
|
|
GROUP BY salarie_corr,date_orig
|
|
HAVING array_agg(abs_cod) && ARRAY['RRH','AMITH']
|
|
;
|
|
|
|
|
|
UPDATE w_cptres1
|
|
SET temps_absence = temps_valide,
|
|
temps_valide = 0,
|
|
abs_cod = code
|
|
FROM w_tot_absence
|
|
WHERE
|
|
w_cptres1.salarie_corr = w_tot_absence.salarie_corr
|
|
AND w_cptres1.date_orig = w_tot_absence.date_orig
|
|
AND temps_valide != 0
|
|
;
|
|
|
|
-- Transformation de certains types horaires de temps validé en temps d'absence
|
|
UPDATE w_cptres1
|
|
SET
|
|
abs_cod = type_horaire,
|
|
temps_absence = temps_valide,
|
|
temps_valide = 0 - temps_valide
|
|
WHERE
|
|
string_to_array((SELECT replace(valeur, ' ', '') FROM rh.t_divers WHERE code = 'CEGI_PLANNING_FORCE_TYPE_HORAIRE_ABSENCE'),',') <> '{}' AND
|
|
type_horaire = ANY (ARRAY(SELECT string_to_array((SELECT replace(valeur, ' ', '') FROM rh.t_divers WHERE code = 'CEGI_PLANNING_FORCE_TYPE_HORAIRE_ABSENCE'),',')))
|
|
;
|
|
|
|
-- Transfert du temps comptabilisé comme du temps_validé vers le temps_du
|
|
UPDATE w_cptres1
|
|
SET
|
|
temps_du = temps_valide,
|
|
temps_valide = 0
|
|
WHERE
|
|
string_to_array((SELECT replace(valeur, ' ', '') FROM rh.t_divers WHERE code = 'CEGI_PLANNING_TYPE_HORAIRE_TEMPS_VALIDE_VERS_TEMPS_DU'),',') <> '{}'
|
|
AND type_horaire = ANY (ARRAY(SELECT STRING_TO_ARRAY((SELECT replace(valeur, ' ', '') FROM rh.t_divers WHERE code = 'CEGI_PLANNING_TYPE_HORAIRE_TEMPS_VALIDE_VERS_TEMPS_DU'),',')))
|
|
;
|
|
|
|
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.
|
|
-- Màj des Services du Planning.
|
|
INSERT INTO rh.t_planning_service(code_original, code, texte, texte_court, service_id)
|
|
SELECT
|
|
code_original,
|
|
code,
|
|
texte,
|
|
substr(texte,1,50),
|
|
0
|
|
FROM w_GNPLA
|
|
WHERE code_original NOT IN (SELECT code_original FROM rh.t_planning_service WHERE code_original IS NOT NULL)
|
|
GROUP BY 1,2,3,4
|
|
;
|
|
|
|
-- Màj des Niveaux du Planning.
|
|
INSERT INTO rh.t_planning_niveau(code_original, code, texte, texte_court)
|
|
SELECT
|
|
code_original,
|
|
code,
|
|
texte,
|
|
substr(texte,1,50)
|
|
FROM w_GNPLA
|
|
WHERE code_original NOT IN (SELECT code_original FROM rh.t_planning_niveau WHERE code_original IS NOT NULL)
|
|
GROUP BY 1,2,3,4
|
|
;
|
|
|
|
-- Màj des Qualifications du Planning.
|
|
INSERT INTO rh.t_planning_qualification(code_original, code, texte, texte_court)
|
|
SELECT
|
|
prs_code,
|
|
prs_code,
|
|
prs_lib,
|
|
prs_lib
|
|
FROM prod_cegi.GNPRS
|
|
WHERE 1=1
|
|
AND prs_code IN (SELECT prs_code FROM w_cptres1)
|
|
AND prs_code NOT IN (SELECT code_original FROM rh.t_planning_qualification WHERE code_original IS NOT NULL)
|
|
;
|
|
|
|
-- Màj des Types d'absences du Planning.
|
|
INSERT INTO rh.t_planning_type_absence(code_original, code, texte, texte_court)
|
|
SELECT
|
|
abspar_id,
|
|
abspar_code,
|
|
abspar_libelle,
|
|
abspar_libelle
|
|
FROM prod_cegi.PYABSENCEPARAM
|
|
WHERE 1=1
|
|
AND abspar_id NOT IN (SELECT code_original FROM rh.t_planning_type_absence WHERE code_original IS NOT NULL)
|
|
AND abspar_code IN (SELECT abs_cod FROM w_cptres1 GROUP BY 1)
|
|
AND abspar_code != ''
|
|
GROUP BY 1,2,3,4
|
|
;
|
|
|
|
-- Conversion code absence selon PYABSENCEPARAM
|
|
UPDATE w_cptres1
|
|
SET abs_cod = ABSPAR_ID
|
|
FROM prod_cegi.PYABSENCEPARAM
|
|
JOIN rh.t_planning_type_absence ON t_planning_type_absence.code_original = PYABSENCEPARAM.ABSPAR_ID
|
|
WHERE ABS_COD = ABSPAR_CODE AND
|
|
abs_cod <> ''
|
|
;
|
|
|
|
INSERT INTO rh.t_planning_type_absence(code_original, code, texte, texte_court)
|
|
SELECT
|
|
dphl_code,
|
|
dphl_code,
|
|
MAX(dphl_lib),
|
|
MAX(dphl_lib)
|
|
FROM prod_cegi.GNDPHL
|
|
WHERE 1=1
|
|
AND dphl_code NOT IN (SELECT code_original FROM rh.t_planning_type_absence WHERE code_original IS NOT NULL)
|
|
AND dphl_code IN (SELECT abs_cod FROM w_cptres1 GROUP BY 1)
|
|
AND dphl_code != ''
|
|
GROUP BY 1,2
|
|
;
|
|
|
|
-- Codes horaires
|
|
INSERT INTO rh.t_planning_code_horaire(code_original, code, texte, texte_court)
|
|
SELECT
|
|
SER_CODE,
|
|
SER_CODE,
|
|
SER_CODE,
|
|
SER_CODE
|
|
FROM w_cptres1
|
|
WHERE 1=1
|
|
AND SER_CODE NOT IN (SELECT code_original FROM rh.t_planning_code_horaire WHERE code_original IS NOT NULL)
|
|
GROUP BY 1
|
|
;
|
|
|
|
-- Création d'une table Entreprise/Etablissement.
|
|
DROP TABLE IF EXISTS w_entets
|
|
;
|
|
|
|
CREATE TEMP TABLE w_entets AS
|
|
select
|
|
MIN(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 2
|
|
;
|
|
|
|
-- Alimentation de la table de mouvement.
|
|
SELECT base.cti_execute('TRUNCATE rh.p_planning_mouvement',1)
|
|
WHERE '[ENV_PLANNING_DATEDEBUT]' = '0001-01-01' AND
|
|
'[ENV_PLANNING_DATEFIN]' = '2099-12-31'
|
|
;
|
|
DELETE FROM rh.p_planning_mouvement
|
|
WHERE date BETWEEN '[ENV_PLANNING_DATEDEBUT]'::date and '[ENV_PLANNING_DATEFIN]'::date
|
|
;
|
|
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,
|
|
temps_du_initial,
|
|
temps_valide,
|
|
temps_absence)
|
|
SELECT
|
|
salarie_id,
|
|
contrat_id,
|
|
contrat_mois_id,
|
|
CASE WHEN COALESCE(VENTIL_JOUR.valeur,'0') = '1' THEN date ELSE date_orig END,
|
|
to_char(CASE WHEN COALESCE(VENTIL_JOUR.valeur,'0') = '1' THEN date ELSE date_orig END, 'IYYYIW'::text)::numeric AS semaine,
|
|
to_char(CASE WHEN COALESCE(VENTIL_JOUR.valeur,'0') = '1' THEN date ELSE date_orig END, '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,
|
|
coalesce(t_planning_code_horaire.oid, 0) as code_horaire_id,
|
|
temps_valide + temps_absence + temps_du,
|
|
temps_du_initial,
|
|
temps_valide,
|
|
temps_absence
|
|
FROM w_cptres1
|
|
LEFT JOIN rh.t_planning_niveau ON t_planning_niveau.code_original = w_cptres1.niveau_code_original
|
|
LEFT JOIN rh.t_planning_service ON t_planning_service.code_original = w_cptres1.service_code_original
|
|
LEFT JOIN rh.t_planning_qualification ON t_planning_qualification.code_original = w_cptres1.prs_code
|
|
LEFT JOIN rh.t_planning_type_absence ON t_planning_type_absence.code_original = w_cptres1.abs_cod
|
|
LEFT JOIN rh.t_planning_code_horaire ON t_planning_code_horaire.code_original = w_cptres1.SER_CODE
|
|
LEFT JOIN w_entets ON w_entets.entets_code = w_cptres1.entets_code
|
|
LEFT JOIN rh.t_divers VENTIL_JOUR ON VENTIL_JOUR.code = 'VENTIL_JOUR'
|
|
where w_cptres1.date between '[ENV_PLANNING_DATEDEBUT]'::date and '[ENV_PLANNING_DATEFIN]'::date
|
|
;
|
|
|
|
VACUUM ANALYSE rh.p_planning_mouvement
|
|
;
|
|
|
|
]]></sqlcmd>
|
|
</NODE>
|
|
</NODE>
|
|
<NODE name="POST" label="Post traitements">
|
|
<sqlcmd><![CDATA[
|
|
|
|
-- Spécifique Infirmerie protestante pour les hypes horaires EN > 7h
|
|
-- Ramener à 7
|
|
UPDATE rh.p_planning_mouvement SET
|
|
temps_du = CASE WHEN temps_du > 7 THEN 7 ELSE temps_du END,
|
|
temps_du_initial = CASE WHEN temps_du_initial > 7 THEN 7 ELSE temps_du_initial END,
|
|
temps_valide = CASE WHEN temps_valide > 7 THEN 7 ELSE temps_valide END,
|
|
temps_absence = CASE WHEN temps_absence > 7 THEN 7 ELSE temps_absence END
|
|
FROM rh.t_planning_code_horaire,
|
|
base.t_finess
|
|
where t_finess.code = '690793468' AND
|
|
code_horaire_id = t_planning_code_horaire.oid AND
|
|
t_planning_code_horaire.code = 'EN' AND
|
|
(
|
|
temps_du > 7 OR
|
|
temps_du_initial > 7 OR
|
|
temps_valide > 7 OR
|
|
temps_absence > 7
|
|
)
|
|
;
|
|
|
|
-- 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
|
|
;
|
|
|
|
CREATE TEMP TABLE w_clasec_1 AS
|
|
SELECT
|
|
site_code as code,
|
|
site_lib as texte,
|
|
(select oid from rh.t_classes where code = 'PLANIV1') as classe_id
|
|
FROM prod_cegi.GNSITE
|
|
JOIN rh.t_divers ON t_divers.code = 'CEGI_SITE_SERVICE' AND t_divers.valeur = '0'
|
|
GROUP BY 1,2,3
|
|
UNION ALL
|
|
SELECT
|
|
t_etablissements.planning_code as code,
|
|
t_etablissements.planning_code as texte,
|
|
(select oid from rh.t_classes where code = 'PLANIV1') as classe_id
|
|
FROM rh.t_etablissements
|
|
JOIN rh.t_divers ON t_divers.code = 'CEGI_SITE_SERVICE' AND t_divers.valeur = '1'
|
|
WHERE planning_code != '*'
|
|
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
|
|
;
|
|
|
|
|
|
SELECT base.cti_execute('
|
|
CREATE TEMP TABLE w_clasec_2 AS
|
|
WITH nb_niv AS (
|
|
SELECT
|
|
typeqp_code, count(DISTINCT typeqp_lib) as niv_count
|
|
FROM prod_cegi.GNTYPEQP
|
|
GROUP BY 1
|
|
)
|
|
SELECT
|
|
CASE WHEN niv_count = 1 THEN GNEQP.typeqp_code else site_code || ''|'' || GNEQP.typeqp_code END as code,
|
|
site_code || ''|'' || GNEQP.typeqp_code as code_original,
|
|
typeqp_lib as texte,
|
|
(select oid from rh.t_classes where code = ''PLANIV2'') as classe_id
|
|
from prod_cegi.GNEQP
|
|
JOIN prod_cegi.GNSITE ON GNEQP.site_id = GNSITE.site_id
|
|
LEFT JOIN prod_cegi.GNTYPEQP ON GNEQP.typeqp_code = GNTYPEQP.typeqp_code
|
|
JOIN nb_niv ON nb_niv.typeqp_code = GNTYPEQP.typeqp_code
|
|
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 prod_cegi.GNSITE',1)
|
|
WHERE (SELECT code FROM rh.t_divers WHERE code = 'CEGI_SITE_SERVICE' and valeur = '0') IS NOT NULL;
|
|
;
|
|
|
|
SELECT base.cti_execute('
|
|
CREATE TEMP TABLE w_clasec_2 AS
|
|
SELECT
|
|
planning_code || ''|'' || site_code as code,
|
|
planning_code || ''|'' || site_code as code_original,
|
|
site_lib as texte,
|
|
(select oid from rh.t_classes where code = ''PLANIV2'') as classe_id
|
|
FROM prod_cegi.GNSITE
|
|
JOIN rh.t_etablissements ON t_etablissements.planning_code != ''*''
|
|
group by 1,2,3
|
|
UNION ALL
|
|
SELECT
|
|
planning_code || ''|'' || ''NR'',
|
|
planning_code || ''|'' || ''NR'',
|
|
''Non renseigné'',
|
|
(select oid from rh.t_classes where code = ''PLANIV2'') as classe_id
|
|
FROM rh.t_etablissements',1)
|
|
WHERE (SELECT code FROM rh.t_divers WHERE code = 'CEGI_SITE_SERVICE' and valeur = '1') IS NOT NULL;
|
|
;
|
|
|
|
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
|
|
;
|
|
|
|
SELECT base.cti_execute('CREATE TEMP TABLE w_clasec_3 AS
|
|
with nb_niv as (
|
|
select
|
|
eqp_code, count(DISTINCT eqp_lib) as niv_count
|
|
from prod_cegi.GNEQP
|
|
group by 1
|
|
)
|
|
SELECT
|
|
CASE WHEN niv_count = 1 THEN GNEQP.eqp_code ELSE site_code || ''|'' || COALESCE(GNTYPEQP.typeqp_code,''NR'') || ''|'' || GNEQP.eqp_code END as code,
|
|
site_code || ''|'' || COALESCE(GNTYPEQP.typeqp_code,''NR'') || ''|'' || GNEQP.eqp_code as code_original,
|
|
eqp_lib as texte,
|
|
(select oid from rh.t_classes where code = ''PLANIV3'') as classe_id
|
|
FROM prod_cegi.GNSITE
|
|
JOIN prod_cegi.GNEQP ON GNSITE.site_id = GNEQP.site_id
|
|
LEFT JOIN prod_cegi.GNTYPEQP ON GNEQP.typeqp_code = GNTYPEQP.typeqp_code
|
|
JOIN nb_niv ON nb_niv.eqp_code = GNEQP.eqp_code
|
|
group by 1,2,3',1)
|
|
WHERE (SELECT code FROM rh.t_divers WHERE code = 'CEGI_SITE_SERVICE' and valeur = '0') IS NOT NULL;
|
|
;
|
|
|
|
SELECT base.cti_execute('CREATE TEMP TABLE w_clasec_3 AS
|
|
SELECT
|
|
planning_code || ''|'' || site_code || ''|'' || GNEQP.eqp_code as code,
|
|
planning_code || ''|'' || site_code || ''|'' || GNEQP.eqp_code as code_original,
|
|
eqp_lib as texte,
|
|
(select oid from rh.t_classes where code = ''PLANIV3'') as classe_id
|
|
FROM prod_cegi.GNSITE
|
|
JOIN prod_cegi.GNEQP ON GNSITE.site_id = GNEQP.site_id
|
|
JOIN rh.t_etablissements ON t_etablissements.planning_code != ''*''
|
|
group by 1,2,3',1)
|
|
WHERE (SELECT code FROM rh.t_divers WHERE code = 'CEGI_SITE_SERVICE' and valeur = '1') IS NOT NULL;
|
|
;
|
|
|
|
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 t_planning_niveau.code_original = w_clasec_3.code_original
|
|
WHERE t_classes.code = 'PLANIV3'
|
|
group by 1,2
|
|
;
|
|
|
|
SELECT rh.cti_update_schema_classes('*ALL')
|
|
;
|
|
|
|
-- Poles
|
|
SELECT rh.cti_reorganize_pole()
|
|
;
|
|
|
|
-- 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>
|