<?xml version="1.0" encoding="ISO-8859-1"?>
|
|
<ROOT>
|
|
<NODE name="INIT" type="common" />
|
|
<NODE name="PROD" label="Synchronisation données">
|
|
<NODE label="Adaptation table des structures">
|
|
<sqlcmd><![CDATA[
|
|
|
|
-- Ajout du code de l'établissement parent des structures
|
|
DROP TABLE IF EXISTS w_rf_structure
|
|
;
|
|
|
|
CREATE TEMP TABLE w_rf_structure AS
|
|
SELECT
|
|
*,
|
|
CASE
|
|
WHEN strfullname != ''
|
|
THEN (regexp_matches(strfullname, '.+\\(ET\d+)'))[1]
|
|
ELSE ''
|
|
END AS strparentcodevalue
|
|
FROM prod_econnection.rf_structure
|
|
;
|
|
|
|
]]></sqlcmd>
|
|
</NODE>
|
|
<NODE label="Listing des salariés CTI">
|
|
<sqlcmd><![CDATA[
|
|
|
|
-- Recensement des salariés CTI
|
|
DROP TABLE IF EXISTS w_sal_pla
|
|
;
|
|
|
|
CREATE TEMP TABLE w_sal_pla AS
|
|
SELECT
|
|
p_salaries.oid AS salarie_id,
|
|
p_salaries.matricule
|
|
FROM rh.p_salaries
|
|
;
|
|
|
|
-- Création d'index.
|
|
CREATE INDEX w_sal_pla_i_matricule ON w_sal_pla USING btree (matricule)
|
|
;
|
|
|
|
]]></sqlcmd>
|
|
</NODE>
|
|
<NODE label="Récupération des salariés ECONNECTION et de leurs contrats">
|
|
<sqlcmd><![CDATA[
|
|
DROP TABLE IF EXISTS w_empwithcontracts
|
|
;
|
|
|
|
CREATE TEMP TABLE w_empwithcontracts AS
|
|
SELECT
|
|
employee.employeeid,
|
|
w_sal_pla.salarie_id, -- ID CTI
|
|
employee.empnumber,
|
|
contract.contractid,
|
|
contract.constractstdate,
|
|
contract.constractenddate,
|
|
contract.refid_category AS type_contrat, -- 127 Contrat horaire / 169 Forfait jour
|
|
CASE
|
|
WHEN contract.refid_category = 169
|
|
THEN 1
|
|
ELSE 0
|
|
END AS est_forfait_jour,
|
|
contract.contractpercentage AS contrat_pourcentage
|
|
FROM prod_econnection.emp_employee AS employee
|
|
JOIN prod_econnection.emp_contract AS contract ON contract.employeeid = employee.employeeid
|
|
JOIN w_sal_pla ON w_sal_pla.matricule = employee.empnumber -- Pour récupérer salarie_id de CTI
|
|
;
|
|
|
|
]]></sqlcmd>
|
|
</NODE>
|
|
<NODE label="Récupération des données journalières du planning">
|
|
<sqlcmd><![CDATA[
|
|
|
|
DROP SEQUENCE IF EXISTS w_planning_seq
|
|
;
|
|
|
|
CREATE TEMP SEQUENCE w_planning_seq
|
|
;
|
|
|
|
DROP TABLE IF EXISTS w_planning
|
|
;
|
|
|
|
-- Table temporaire de récupération des données du planning
|
|
CREATE TEMP TABLE w_planning AS
|
|
SELECT
|
|
nextval('w_planning_seq') as cptres1_id,
|
|
schedule.scheduleid,
|
|
w_empwithcontracts.salarie_id AS salarie_id, --ID Salarié CTI
|
|
w_empwithcontracts.employeeid, -- ID Salarié ECONNECTION
|
|
w_empwithcontracts.empnumber AS matricule,
|
|
w_empwithcontracts.contractid,
|
|
w_empwithcontracts.est_forfait_jour,
|
|
w_empwithcontracts.contrat_pourcentage,
|
|
null::bigint AS contrat_id,
|
|
null::bigint AS contrat_mois_id,
|
|
date(scheduledate) AS date,
|
|
to_char(scheduledate, 'IYYYIW'::text)::numeric AS semaine,
|
|
to_char(scheduledate, 'YYYYMM'::text)::numeric AS mois,
|
|
''::text AS etablissement_code,
|
|
null::bigint AS etablissement_id,
|
|
''::text AS service_code,
|
|
''::text AS niveau_code,
|
|
''::text AS qualification_code,
|
|
ARRAY[]::text[] AS absences_codes,
|
|
''::text AS horaire_code,
|
|
0::numeric AS temps_du_initial, -- Sert pour stocker le compteur OAT
|
|
0::numeric AS temps_du,
|
|
0::numeric AS temps_valide,
|
|
0::numeric AS temps_presence,
|
|
ARRAY[]::text[] AS temps_absences
|
|
FROM prod_econnection.emp_schedule AS schedule
|
|
JOIN w_empwithcontracts ON w_empwithcontracts.employeeid = schedule.employeeid AND schedule.scheduledate BETWEEN w_empwithcontracts.constractstdate AND w_empwithcontracts.constractenddate
|
|
WHERE scheduledate <= NOW()
|
|
GROUP BY 2,3,4,5,6,7,8,11,12,13
|
|
;
|
|
|
|
VACUUM ANALYZE w_planning
|
|
;
|
|
|
|
]]></sqlcmd>
|
|
</NODE>
|
|
<NODE label="Gestion des codes absences des salariés">
|
|
<sqlcmd><![CDATA[
|
|
|
|
-- Récupération des codes d'absences (codes événements ECONNECTION)
|
|
DROP TABLE IF EXISTS w_codes_absences
|
|
;
|
|
|
|
CREATE TEMP TABLE w_codes_absences AS
|
|
SELECT
|
|
crf_eventcode.eventcodeid,
|
|
crf_eventcode.eventcode,
|
|
crf_dictevc.attvalue
|
|
FROM prod_econnection.crf_eventcode AS crf_eventcode
|
|
JOIN prod_econnection.crf_dictevc AS crf_dictevc ON crf_dictevc.mainobjid = crf_eventcode.eventcodeid AND crf_dictevc.languageid = 1
|
|
WHERE crf_eventcode.evctype = 0 -- Type absence
|
|
;
|
|
|
|
-- Récupération des absences journalières des salariés
|
|
DROP TABLE IF EXISTS w_empabsences
|
|
;
|
|
|
|
CREATE TEMP TABLE w_empabsences AS
|
|
WITH absences_agg AS (
|
|
SELECT
|
|
w_planning.cptres1_id,
|
|
w_planning.scheduleid,
|
|
w_planning.salarie_id,
|
|
w_planning.date,
|
|
eventcode,
|
|
SUM(devent_duration) AS devent_duration
|
|
FROM w_planning
|
|
JOIN prod_econnection.emp_schdailyevent ON emp_schdailyevent.scheduleid = w_planning.scheduleid
|
|
JOIN w_codes_absences ON w_codes_absences.eventcodeid = emp_schdailyevent.eventcodeid
|
|
GROUP BY 1,2,3,4,5
|
|
ORDER BY salarie_id, date
|
|
)
|
|
SELECT
|
|
cptres1_id,
|
|
scheduleid,
|
|
salarie_id,
|
|
date,
|
|
array_agg(eventcode) AS events_codes,
|
|
array_agg(devent_duration) AS devents_durations
|
|
FROM absences_agg
|
|
GROUP BY 1,2,3,4
|
|
ORDER BY salarie_id, date
|
|
;
|
|
|
|
UPDATE w_planning
|
|
SET absences_codes = w_empabsences.events_codes, temps_absences = w_empabsences.devents_durations
|
|
FROM w_empabsences
|
|
WHERE w_planning.cptres1_id = w_empabsences.cptres1_id
|
|
;
|
|
|
|
]]></sqlcmd>
|
|
</NODE>
|
|
<NODE label="Attribution des horaires journaliers aux salariés">
|
|
<sqlcmd><![CDATA[
|
|
|
|
-- Pour les salariés en forfait horaire (standard) + temps_absence utilisé pour les salariés en forfait jour
|
|
UPDATE w_planning
|
|
SET
|
|
temps_du = c_j_tte_oat_h,
|
|
temps_valide = c_j_tte_h,
|
|
temps_presence = c_j_tpres
|
|
FROM prod_econnection.emp_dailycounter
|
|
WHERE emp_dailycounter.employeeid = w_planning.employeeid AND emp_dailycounter.empdaycntdate = w_planning.date
|
|
;
|
|
|
|
-- Attribution arbitraire d'heures pour les salariés en forfait jour
|
|
UPDATE w_planning
|
|
SET
|
|
temps_du = subview.temps_du,
|
|
temps_valide = subview.temps_valide
|
|
FROM (
|
|
with forfait_jour_temps_du AS (
|
|
SELECT
|
|
cptres1_id,
|
|
((151.67 * (contrat_pourcentage / 100) / date_part('days', (date_trunc('month', date) + interval '1 month - 1 day')))::numeric) * 60 AS temps_du,
|
|
temps_absences
|
|
FROM w_planning
|
|
WHERE w_planning.est_forfait_jour = 1
|
|
)
|
|
SELECT
|
|
cptres1_id,
|
|
temps_du,
|
|
temps_absences,
|
|
CASE
|
|
WHEN temps_absences != '{}'
|
|
THEN (temps_du - (base.cti_array_sum(temps_absences::numeric[])))
|
|
ELSE temps_du
|
|
END AS temps_valide
|
|
FROM forfait_jour_temps_du
|
|
) AS subview
|
|
WHERE subview.cptres1_id = w_planning.cptres1_id
|
|
;
|
|
|
|
-- Attribution du compteur annuel OAT
|
|
-- On l'attribue à la première date du planning du salarié
|
|
UPDATE w_planning
|
|
SET temps_du_initial = subview.temps_param_oat_minutes
|
|
FROM (
|
|
SELECT
|
|
w_planning.employeeid,
|
|
MIN(date) AS min_date,
|
|
DATE_PART('YEAR', date) AS annee,
|
|
emp_periodcounter.empprdcntvalue AS temps_param_oat_minutes
|
|
FROM w_planning
|
|
JOIN prod_econnection.emp_periodcounter AS emp_periodcounter ON emp_periodcounter.employeeid = w_planning.employeeid AND DATE_PART('YEAR', date) = DATE_PART('YEAR', empprdcntstdate)
|
|
JOIN prod_econnection.cnt_basiccounter AS cnt_basiccounter ON cnt_basiccounter.basicctid = emp_periodcounter.basicctid
|
|
WHERE cnt_basiccounter.bctcode = 'C_A_OATT_P_H'
|
|
GROUP BY 1,3,4
|
|
) AS subview
|
|
WHERE w_planning.employeeid = subview.employeeid AND w_planning.date = subview.min_date
|
|
;
|
|
|
|
]]></sqlcmd>
|
|
</NODE>
|
|
<NODE label="Gestion des structures/services des salariés">
|
|
<sqlcmd><![CDATA[
|
|
|
|
-- Attribution des structures aux salariés
|
|
DROP TABLE IF EXISTS w_empstructures
|
|
;
|
|
|
|
CREATE TEMP TABLE w_empstructures AS
|
|
SELECT
|
|
cptres1_id,
|
|
w_planning.date,
|
|
empstructure.employeeid,
|
|
array_agg(COALESCE(empstructure.structureid, 0) ORDER BY empstrisfirst DESC) AS structuresid
|
|
FROM w_planning
|
|
JOIN prod_econnection.emp_empstructure AS empstructure ON empstructure.employeeid = w_planning.employeeid
|
|
WHERE w_planning.employeeid = empstructure.employeeid AND w_planning.date BETWEEN empstructure.empstrstdate AND empstructure.empstrenddate
|
|
GROUP BY 1,2,3
|
|
;
|
|
|
|
-- Attribution des services en fonction des prêts
|
|
DROP TABLE IF EXISTS w_empservices
|
|
;
|
|
|
|
CREATE TEMP TABLE w_empservices AS
|
|
SELECT
|
|
w_planning.cptres1_id,
|
|
w_planning.date,
|
|
w_empstructures.employeeid,
|
|
CASE
|
|
WHEN emp_str_exchange.empexchid IS NOT NULL -- Si il y a prêt du salarié, on prend la structure de prêt attribué
|
|
THEN emp_str_exchange.structureid
|
|
ELSE w_empstructures.structuresid[1] -- Sinon, on prend la structure principale de l'employé
|
|
END AS structureid,
|
|
CASE
|
|
WHEN emp_str_exchange.empexchid IS NOT NULL -- Si il y a prêt du salarié, on prend la structure de prêt attribué
|
|
THEN emp_str_exchange.structureid
|
|
ELSE w_empstructures.structuresid[1] -- Sinon, on prend la structure principale de l'employé
|
|
END AS structure_code,
|
|
CASE
|
|
WHEN emp_str_exchange.empexchid IS NOT NULL
|
|
THEN 1
|
|
ELSE 0
|
|
END AS salarie_prete,
|
|
w_empstructures.structuresid[1] AS structure_origine
|
|
FROM w_planning
|
|
JOIN w_empstructures ON w_empstructures.cptres1_id = w_planning.cptres1_id
|
|
LEFT JOIN prod_econnection.emp_str_exchange AS emp_str_exchange ON emp_str_exchange.employeeid = w_planning.employeeid AND w_planning.date BETWEEN emp_str_exchange.empexch_stdate AND emp_str_exchange.empexch_enddate
|
|
;
|
|
|
|
-- Mise à jour du code service/code etablissement pour le planning des salariés
|
|
UPDATE w_planning
|
|
SET service_code = subview.service_code,
|
|
etablissement_code = subview.etablissement_code
|
|
FROM
|
|
(
|
|
SELECT
|
|
cptres1_id,
|
|
rf_structure.strcodevalue AS service_code,
|
|
rf_structure.strparentcodevalue AS etablissement_code
|
|
FROM w_empservices
|
|
LEFT JOIN w_rf_structure AS rf_structure ON rf_structure.strid = w_empservices.structureid
|
|
) AS subview
|
|
WHERE w_planning.cptres1_id = subview.cptres1_id
|
|
;
|
|
|
|
]]></sqlcmd>
|
|
</NODE>
|
|
<NODE label="Gestion des contrats des salariés">
|
|
<sqlcmd><![CDATA[
|
|
|
|
-- Association aux contrats et contrat_mois.
|
|
-- En général, les heures planning sont effectuées AVANT un contrat/paie à cause du décallage avec la paie :
|
|
-- => les heures effectuées en fin de mois sont à associer avec le mois suivant.
|
|
with w_asso as (
|
|
select
|
|
cptres1_id,
|
|
(max(array[extract(epoch from p_contrats_mois.date_debut), p_contrats_mois.contrat_id]))[2] as contrat_id,
|
|
(max(array[extract(epoch from p_contrats_mois.date_debut), p_contrats_mois.oid]))[2] as contrat_mois_id
|
|
from w_planning
|
|
join rh.p_contrats_mois on 1=1
|
|
and p_contrats_mois.salarie_id = w_planning.salarie_id
|
|
and w_planning.date between p_contrats_mois.date_debut and p_contrats_mois.date_fin -- Sélection des contrats pendant heures planning.
|
|
where 1!=1
|
|
OR w_planning.contrat_id is null
|
|
OR w_planning.contrat_mois_id is null
|
|
group by 1)
|
|
UPDATE w_planning SET
|
|
contrat_id = w_asso.contrat_id,
|
|
contrat_mois_id = w_asso.contrat_mois_id
|
|
FROM w_asso
|
|
WHERE w_planning.cptres1_id = w_asso.cptres1_id
|
|
;
|
|
|
|
with w_asso as (
|
|
select
|
|
cptres1_id,
|
|
(min(array[extract(epoch from p_contrats_mois.date_debut), p_contrats_mois.contrat_id]))[2] as contrat_id,
|
|
(min(array[extract(epoch from p_contrats_mois.date_debut), p_contrats_mois.oid]))[2] as contrat_mois_id
|
|
from w_planning
|
|
join rh.p_contrats_mois on 1=1
|
|
and p_contrats_mois.salarie_id = w_planning.salarie_id
|
|
and p_contrats_mois.date_debut > w_planning.date -- Sélection des contrats APRES heures planning.
|
|
where 1!=1
|
|
OR w_planning.contrat_id is null
|
|
OR w_planning.contrat_mois_id is null
|
|
group by 1)
|
|
UPDATE w_planning SET
|
|
contrat_id = w_asso.contrat_id,
|
|
contrat_mois_id = w_asso.contrat_mois_id
|
|
FROM w_asso
|
|
WHERE w_planning.cptres1_id = w_asso.cptres1_id
|
|
;
|
|
|
|
with w_asso as (
|
|
select
|
|
cptres1_id,
|
|
(max(array[extract(epoch from p_contrats_mois.date_debut), p_contrats_mois.contrat_id]))[2] as contrat_id,
|
|
(max(array[extract(epoch from p_contrats_mois.date_debut), p_contrats_mois.oid]))[2] as contrat_mois_id
|
|
from w_planning
|
|
join rh.p_contrats_mois on 1=1
|
|
and p_contrats_mois.salarie_id = w_planning.salarie_id
|
|
and p_contrats_mois.date_debut < w_planning.date -- Sélection des contrats AVANT heures planning.
|
|
where 1!=1
|
|
OR w_planning.contrat_id is null
|
|
OR w_planning.contrat_mois_id is null
|
|
group by 1)
|
|
UPDATE w_planning SET
|
|
contrat_id = w_asso.contrat_id,
|
|
contrat_mois_id = w_asso.contrat_mois_id
|
|
FROM w_asso
|
|
WHERE w_planning.cptres1_id = w_asso.cptres1_id
|
|
;
|
|
|
|
-- Création d'index.
|
|
CREATE INDEX w_planning_i_contrat_id ON w_planning USING btree (contrat_id)
|
|
;
|
|
CREATE INDEX w_planning_i_contrat_mois_id ON w_planning USING btree (contrat_mois_id)
|
|
;
|
|
CREATE INDEX w_planning_i_date ON w_planning USING btree (date)
|
|
;
|
|
CREATE INDEX w_planning_i_salarie_id ON w_planning USING btree (salarie_id)
|
|
;
|
|
|
|
]]></sqlcmd>
|
|
</NODE>
|
|
|
|
<NODE label="Gestion des compétences des salariés">
|
|
<sqlcmd><![CDATA[
|
|
|
|
-- Gestion des compétences (qualifications)
|
|
DROP TABLE IF EXISTS w_competences
|
|
;
|
|
|
|
CREATE TEMP TABLE w_competences AS
|
|
SELECT
|
|
crf_competence.compcode,
|
|
pjr_translationitem.translated AS comptexte
|
|
FROM prod_econnection.crf_competence AS crf_competence
|
|
JOIN prod_econnection.rf_label AS rf_label ON rf_label.lblid = crf_competence.lblid
|
|
JOIN prod_econnection.pjr_translationitem AS pjr_translationitem ON pjr_translationitem.translid = crf_competence.translid_compname AND pjr_translationitem.languageid = 1
|
|
;
|
|
|
|
-- On regarde le contrat du salarié pour connaître son poste si celui-ci n'était pas renseigné dans les données planning
|
|
UPDATE w_planning
|
|
SET qualification_code = compcode
|
|
FROM
|
|
(
|
|
SELECT
|
|
empnumber,
|
|
contractid,
|
|
COALESCE(compcode, '') AS compcode
|
|
FROM prod_econnection.emp_employee AS employee
|
|
JOIN prod_econnection.emp_contract AS contract ON contract.employeeid = employee.employeeid
|
|
JOIN prod_econnection.rf_reference AS rf_reference ON rf_reference.refid = contract.refid_qualification
|
|
LEFT JOIN w_competences ON w_competences.compcode = substring(rf_reference.refcode, 0, 5)
|
|
) AS subview
|
|
WHERE w_planning.matricule = subview.empnumber AND w_planning.contractid = subview.contractid
|
|
;
|
|
|
|
]]></sqlcmd>
|
|
</NODE>
|
|
<NODE label="Gestion des codes horaires du planning des salariés">
|
|
<sqlcmd><![CDATA[
|
|
|
|
-- Formattage des codes horaires pour chaque entrée dans le planning
|
|
DROP TABLE IF EXISTS w_codes_horaires_planning
|
|
;
|
|
|
|
CREATE TEMP TABLE w_codes_horaires_planning AS
|
|
SELECT
|
|
emp_schedule_tc.scheduleid,
|
|
crf_timecode.tcdesc AS code_desc,
|
|
CASE
|
|
WHEN crf_timecode.code_interne NOT LIKE crf_timecode.tcabrname
|
|
THEN crf_timecode.code_interne || '(' || crf_timecode.tcabrname || ')'
|
|
ELSE crf_timecode.code_interne
|
|
END AS code
|
|
FROM prod_econnection.emp_schedule_tc AS emp_schedule_tc
|
|
LEFT JOIN prod_econnection.crf_timecode AS crf_timecode ON crf_timecode.timecodeid = emp_schedule_tc.timecodeid
|
|
;
|
|
|
|
-- Attribution d'un code horaire généré dans les données du planning
|
|
UPDATE w_planning
|
|
SET horaire_code = sub.code
|
|
FROM w_codes_horaires_planning AS sub
|
|
WHERE sub.scheduleid = w_planning.scheduleid
|
|
;
|
|
|
|
VACUUM ANALYZE w_planning
|
|
;
|
|
|
|
]]></sqlcmd>
|
|
</NODE>
|
|
<NODE label="Gestion des entreprises/établissements">
|
|
<sqlcmd><![CDATA[
|
|
|
|
-- Création d'une table Entreprise/Etablissement.
|
|
DROP TABLE IF EXISTS w_entets
|
|
;
|
|
|
|
CREATE TEMP TABLE w_entets AS
|
|
select
|
|
max(ent.oid) as entreprise_id,
|
|
max(ets.oid) as etablissement_id,
|
|
ent.planning_code||ets.planning_code as entets_code
|
|
from rh.t_entreprises as ent
|
|
join rh.t_etablissements as ets on ets.entreprise_id = ent.oid
|
|
Where 1=1
|
|
and ent.oid != 0
|
|
and ets.oid != 0
|
|
GROUP BY ent.planning_code||ets.planning_code
|
|
;
|
|
|
|
]]></sqlcmd>
|
|
</NODE>
|
|
<NODE label="Alimentation des différentes tables de paramétres">
|
|
<sqlcmd><![CDATA[
|
|
|
|
-- Alimentation des tables de paramètres.
|
|
-- Màj des Services du Planning.
|
|
INSERT INTO rh.t_planning_service(code_original, code, texte, texte_court, service_id)
|
|
SELECT
|
|
strcodevalue AS code_original,
|
|
strcodevalue AS code,
|
|
strabrname AS texte,
|
|
strabrname AS texte_court,
|
|
0 AS service_id
|
|
FROM w_rf_structure
|
|
WHERE strcodevalue NOT IN (SELECT code_original FROM rh.t_planning_service WHERE code_original IS NOT NULL)
|
|
GROUP BY 1,2,3,4,5
|
|
;
|
|
|
|
-- Màj des Niveaux du Planning.
|
|
-- Insertion des nouveaux niveaux de planning.
|
|
INSERT INTO rh.t_planning_niveau(code_original, code, texte, texte_court)
|
|
SELECT
|
|
strcodevalue AS code_original,
|
|
strcodevalue AS code,
|
|
strfullname AS texte,
|
|
strname AS texte_court
|
|
FROM w_rf_structure AS rf_structure -- en fait t_planning_niveau
|
|
WHERE strlevel = 2 -- Niveaux ?
|
|
--AND rf_structure.strcodevalue IN (SELECT rf_structure.strcodevalue FROM w_planning)
|
|
AND strcodevalue 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
|
|
compcode AS code_original,
|
|
compcode AS code,
|
|
comptexte AS texte,
|
|
comptexte texte_court
|
|
FROM w_competences
|
|
WHERE 1=1
|
|
AND w_competences.compcode IN (SELECT qualification_code FROM w_planning)
|
|
AND w_competences.compcode NOT IN (SELECT code_original FROM rh.t_planning_qualification WHERE code_original IS NOT NULL)
|
|
;
|
|
|
|
-- On met à jour les qualifications planning avec les ids correspondant aux qualifications rh
|
|
-- On renseigne les ids des qualifications pouvant être associées à une qualification déja existante
|
|
|
|
-- Ajout de la fonction unaccent via Extension Postgres
|
|
CREATE EXTENSION IF NOT EXISTS unaccent
|
|
;
|
|
|
|
UPDATE rh.t_planning_qualification
|
|
SET qualification_id = subview.qualification_id
|
|
FROM (
|
|
with maxlength AS
|
|
(
|
|
SELECT
|
|
MAX(length(texte)) AS value
|
|
FROM rh.t_qualifications
|
|
),
|
|
competences AS
|
|
(
|
|
SELECT
|
|
crf_competence.compcode,
|
|
pjr_translationitem.translated AS comptexte
|
|
FROM prod_econnection.crf_competence AS crf_competence
|
|
JOIN prod_econnection.rf_label AS rf_label ON rf_label.lblid = crf_competence.lblid
|
|
JOIN prod_econnection.pjr_translationitem AS pjr_translationitem ON pjr_translationitem.translid = crf_competence.translid_compname AND pjr_translationitem.languageid = 1
|
|
)
|
|
SELECT
|
|
MAX(t_qualifications.code_original) AS compcode,
|
|
competences.compcode AS compcode_original,
|
|
t_qualifications.oid AS qualification_id,
|
|
t_qualifications.texte AS comptexte
|
|
FROM
|
|
competences, rh.t_qualifications AS t_qualifications, maxlength
|
|
WHERE replace(trim(lower(t_qualifications.texte)), '-', ' ') = replace(trim(lower(unaccent(substring(competences.comptexte, 1, maxlength.value)))), '-', ' ')
|
|
GROUP BY 2,3
|
|
ORDER BY texte
|
|
) AS subview
|
|
WHERE subview.compcode_original = code_original
|
|
;
|
|
|
|
-- Màj des Types d'absences du Planning.
|
|
INSERT INTO rh.t_planning_type_absence(code_original, code, texte, texte_court)
|
|
SELECT
|
|
crf_eventcode.eventcode AS code_original,
|
|
crf_eventcode.eventcode AS code,
|
|
SUBSTRING(crf_dictevc.attvalue, 0, 250) AS texte,
|
|
SUBSTRING(crf_dictevc.attvalue, 0, 50) AS texte_court
|
|
FROM prod_econnection.crf_eventcode AS crf_eventcode
|
|
JOIN prod_econnection.crf_dictevc AS crf_dictevc ON crf_dictevc.mainobjid = crf_eventcode.eventcodeid AND crf_dictevc.languageid = 1
|
|
WHERE 1=1
|
|
AND crf_eventcode.evctype = 0 -- Type absence
|
|
AND crf_eventcode.eventcode NOT IN (SELECT code_original FROM rh.t_planning_type_absence WHERE code_original IS NOT NULL)
|
|
;
|
|
|
|
-- Màj des Codes Horaires du Planning.
|
|
INSERT INTO rh.t_planning_code_horaire(code_original, code, texte, texte_court)
|
|
SELECT
|
|
code AS code_original,
|
|
code,
|
|
SUBSTRING(code_desc, 0, 50) AS texte,
|
|
SUBSTRING(code_desc, 0, 50) AS texte_court
|
|
FROM w_codes_horaires_planning
|
|
WHERE 1=1
|
|
AND code NOT IN (SELECT code_original FROM rh.t_planning_code_horaire WHERE code_original IS NOT NULL)
|
|
GROUP BY 1,2,3,4
|
|
;
|
|
|
|
]]></sqlcmd>
|
|
</NODE>
|
|
<NODE label="Alimentation de la table des mouvements du planning">
|
|
<sqlcmd><![CDATA[
|
|
-- Dépilement codes absences/temps absences (unnest)
|
|
DROP TABLE IF EXISTS w_planning_et_absences
|
|
;
|
|
|
|
CREATE TEMP TABLE w_planning_et_absences AS
|
|
with unnested AS (
|
|
SELECT
|
|
*,
|
|
CASE
|
|
WHEN absences_codes != '{}'
|
|
THEN unnest(absences_codes)
|
|
ELSE ''
|
|
END AS absence_code,
|
|
CASE
|
|
WHEN temps_absences != '{}'
|
|
THEN unnest(temps_absences)::numeric
|
|
ELSE 0
|
|
END AS temps_absence
|
|
FROM w_planning
|
|
)
|
|
SELECT
|
|
*,
|
|
CASE
|
|
WHEN array_length(absences_codes, 1) > 1 AND temps_du_initial > 0
|
|
THEN temps_du_initial / array_length(absences_codes, 1)
|
|
ELSE temps_du_initial
|
|
END AS temps_du_initial_final,
|
|
CASE
|
|
WHEN array_length(absences_codes, 1) > 1 AND temps_du > 0
|
|
THEN temps_du / array_length(absences_codes, 1)
|
|
ELSE temps_du
|
|
END AS temps_du_final,
|
|
CASE
|
|
WHEN array_length(absences_codes, 1) > 1 AND temps_valide > 0
|
|
THEN temps_valide / array_length(absences_codes, 1)
|
|
ELSE temps_valide
|
|
END AS temps_valide_final,
|
|
temps_absence AS temps_absence_final,
|
|
temps_presence AS temps_presence_final
|
|
FROM unnested
|
|
;
|
|
|
|
-- Alimentation de la table de mouvement.
|
|
TRUNCATE rh.p_planning_mouvement
|
|
;
|
|
|
|
INSERT INTO rh.p_planning_mouvement(
|
|
salarie_id,
|
|
contrat_id,
|
|
contrat_mois_id,
|
|
date,
|
|
semaine,
|
|
mois,
|
|
etablissement_id, -- @todo à renseigner en fonction du paramétrage dans t_divers.
|
|
service_id,
|
|
qualification_id,
|
|
type_absence_id,
|
|
niveau_id,
|
|
code_horaire_id,
|
|
temps_du_initial,
|
|
temps_du,
|
|
temps_du_ajuste,
|
|
temps_valide,
|
|
temps_valide_ajuste,
|
|
temps_presence,
|
|
temps_presence_ajuste,
|
|
temps_absence,
|
|
temps_absence_ajuste)
|
|
SELECT
|
|
w_planning_et_absences.salarie_id,
|
|
w_planning_et_absences.contrat_id,
|
|
w_planning_et_absences.contrat_mois_id,
|
|
w_planning_et_absences.date,
|
|
w_planning_et_absences.semaine,
|
|
w_planning_et_absences.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,
|
|
ROUND(w_planning_et_absences.temps_du_initial_final / 60, 4) AS temps_du_initial,
|
|
ROUND(w_planning_et_absences.temps_du_final / 60, 4) AS temps_du,
|
|
ROUND(w_planning_et_absences.temps_du_final / 60, 4) AS temps_du_ajuste,
|
|
ROUND(w_planning_et_absences.temps_valide_final / 60, 4) AS temps_valide,
|
|
ROUND(w_planning_et_absences.temps_valide_final / 60, 4) AS temps_valide_ajuste,
|
|
ROUND(w_planning_et_absences.temps_presence_final / 60, 4) AS temps_presence,
|
|
ROUND(w_planning_et_absences.temps_presence_final / 60, 4) AS temps_presence_ajuste,
|
|
ROUND(w_planning_et_absences.temps_absence_final / 60, 4) AS temps_absence,
|
|
ROUND(w_planning_et_absences.temps_absence_final / 60, 4) AS temps_absence_ajuste
|
|
FROM w_planning_et_absences
|
|
JOIN rh.p_salaries ON p_salaries.oid = w_planning_et_absences.salarie_id
|
|
JOIN w_entets ON w_entets.entreprise_id = p_salaries.entreprise_id
|
|
LEFT JOIN rh.t_planning_niveau ON t_planning_niveau.code_original = w_planning_et_absences.niveau_code--_original
|
|
LEFT JOIN rh.t_planning_service ON t_planning_service.code_original = w_planning_et_absences.service_code--_original
|
|
LEFT JOIN rh.t_planning_qualification ON t_planning_qualification.code_original = w_planning_et_absences.qualification_code
|
|
LEFT JOIN rh.t_planning_type_absence ON t_planning_type_absence.code_original = w_planning_et_absences.absence_code
|
|
LEFT JOIN rh.t_planning_code_horaire ON t_planning_code_horaire.code_original = w_planning_et_absences.horaire_code
|
|
GROUP BY 1,2,3,4,5,6,7,8,9,10,11,12,13,14,15,16,17,18,19,20,21
|
|
;
|
|
|
|
VACUUM ANALYSE rh.p_planning_mouvement
|
|
;
|
|
|
|
]]></sqlcmd>
|
|
</NODE>
|
|
</NODE>
|
|
<NODE name="POST" type="common" />
|
|
<NODE name="VACUUM" type="common" />
|
|
</ROOT>
|