<?xml version="1.0" encoding="ISO-8859-1"?>
|
|
<ROOT>
|
|
<NODE name="INIT" type="common" />
|
|
<NODE name="PROD" label="Synchronisation données">
|
|
<NODE label="Matérialisation des tables gestor">
|
|
<sqlcmd><![CDATA[
|
|
|
|
-- Technique : reconstitution d'une table parente à partir des tables filles contenant les données pour chaque année.
|
|
DROP TABLE IF EXISTS prod_gestor_compteurj
|
|
;
|
|
CREATE TEMP TABLE prod_gestor_compteurj AS
|
|
SELECT *, ''::text AS salarie_corr
|
|
FROM prod_gestor.compteurj
|
|
;
|
|
|
|
DELETE FROM prod_gestor_compteurj
|
|
USING prod_gestor.JPTGS
|
|
WHERE 1=1
|
|
AND JPTGS.datej = prod_gestor_compteurj.datej
|
|
AND JPTGS.nummat = prod_gestor_compteurj.nummat
|
|
AND cycle = '{MODELE}'
|
|
AND indnuit = 1
|
|
;
|
|
|
|
DROP TABLE IF EXISTS prod_gestor_absence
|
|
;
|
|
CREATE TEMP TABLE prod_gestor_absence AS
|
|
SELECT absprev.*, ''::text AS salarie_corr
|
|
FROM prod_gestor.absprev
|
|
JOIN prod_gestor.codeevt ON absprev.code = codeevt.code
|
|
WHERE
|
|
famregroup != 1
|
|
;
|
|
|
|
DROP TABLE IF EXISTS prod_gestor_niveaux2
|
|
;
|
|
CREATE TEMP TABLE prod_gestor_niveaux2 AS
|
|
SELECT niv_code, MAX(libelle) as libelle
|
|
FROM prod_gestor.niveaux2
|
|
GROUP BY 1
|
|
;
|
|
|
|
DROP TABLE IF EXISTS prod_gestor_pers
|
|
;
|
|
CREATE TEMP TABLE prod_gestor_pers AS
|
|
SELECT
|
|
nummat,
|
|
matricule,
|
|
niv1,
|
|
niv2,
|
|
niv3,
|
|
niv4,
|
|
niv5
|
|
FROM prod_gestor.personnel
|
|
GROUP BY 1,2,3,4,5,6,7
|
|
;
|
|
|
|
DROP TABLE IF EXISTS w_histo_ser;
|
|
CREATE TEMP TABLE w_histo_ser AS
|
|
SELECT
|
|
nummat,
|
|
datedeb,
|
|
datefin,
|
|
niv1,
|
|
niv2::text,
|
|
niv3,
|
|
niv4,
|
|
niv5,
|
|
''::text AS niv_cod1,
|
|
''::text AS niv_cod2,
|
|
''::text AS niv_cod3,
|
|
''::text AS niv_cod4,
|
|
''::text AS niv_cod5
|
|
FROM prod_gestor.historique
|
|
GROUP BY 1,2,3,4,5,6,7,8
|
|
;
|
|
|
|
UPDATE w_histo_ser
|
|
SET datefin = datedeb,
|
|
datedeb = datefin
|
|
WHERE datefin < datedeb;
|
|
|
|
UPDATE w_histo_ser
|
|
SET datedeb = w_histo_ser_ref.datefin + '1 day'::interval
|
|
FROM w_histo_ser w_histo_ser_ref
|
|
WHERE w_histo_ser.nummat = w_histo_ser_ref.nummat AND w_histo_ser.datedeb between w_histo_ser_ref.datedeb AND w_histo_ser_ref.datefin AND
|
|
(w_histo_ser.datedeb != w_histo_ser_ref.datedeb OR w_histo_ser.datefin != w_histo_ser_ref.datefin) AND
|
|
w_histo_ser.niv1 = w_histo_ser_ref.niv1 AND
|
|
w_histo_ser.niv2 = w_histo_ser_ref.niv2 AND
|
|
w_histo_ser.niv3 = w_histo_ser_ref.niv3 AND
|
|
w_histo_ser.niv4 = w_histo_ser_ref.niv4 AND
|
|
w_histo_ser.niv5 = w_histo_ser_ref.niv5 AND
|
|
w_histo_ser.datefin != w_histo_ser.datedeb
|
|
;
|
|
|
|
DELETE FROM w_histo_ser
|
|
USING w_histo_ser w_histo_ser_ref
|
|
WHERE w_histo_ser.nummat = w_histo_ser_ref.nummat AND w_histo_ser.datedeb between w_histo_ser_ref.datedeb AND w_histo_ser_ref.datefin AND
|
|
(w_histo_ser.datedeb != w_histo_ser_ref.datedeb OR w_histo_ser.datefin != w_histo_ser_ref.datefin) AND
|
|
w_histo_ser.niv1 = w_histo_ser_ref.niv1 AND
|
|
w_histo_ser.niv2 = w_histo_ser_ref.niv2 AND
|
|
w_histo_ser.niv3 = w_histo_ser_ref.niv3 AND
|
|
w_histo_ser.niv4 = w_histo_ser_ref.niv4 AND
|
|
w_histo_ser.niv5 = w_histo_ser_ref.niv5 AND
|
|
w_histo_ser.datefin = w_histo_ser.datedeb
|
|
;
|
|
|
|
DROP TABLE IF EXISTS w_histo_ser_overlap;
|
|
CREATE TEMP TABLE w_histo_ser_overlap AS
|
|
SELECT
|
|
histo.nummat, histo.datedeb,histo.datefin,histo2.datedeb as datedeb_ref,histo2.datefin as datefin_ref,histo2.niv1,histo2.niv2,histo2.niv3,histo2.niv4,histo2.niv5
|
|
FROM prod_gestor.historique histo
|
|
JOIN prod_gestor.historique histo2 ON histo.nummat = histo2.nummat AND histo2.datedeb between histo.datedeb AND histo.datefin AND
|
|
(
|
|
histo.niv1 != histo2.niv1 OR
|
|
histo.niv2 != histo2.niv2 OR
|
|
histo.niv3 != histo2.niv3 OR
|
|
histo.niv4 != histo2.niv4 OR
|
|
histo.niv5 != histo2.niv5
|
|
)
|
|
GROUP BY 1,2,3,4,5,6,7,8,9,10
|
|
;
|
|
|
|
-- réduit date de fin si date fin overlap supérieure
|
|
UPDATE w_histo_ser
|
|
SET
|
|
datefin = w_histo_ser_overlap.datedeb - '1 day'::interval
|
|
FROM w_histo_ser_overlap
|
|
WHERE 1=1
|
|
AND w_histo_ser_overlap.nummat = w_histo_ser.nummat
|
|
AND w_histo_ser_overlap.datefin > w_histo_ser.datefin
|
|
AND w_histo_ser_overlap.datedeb BETWEEN w_histo_ser.datedeb AND w_histo_ser.datefin
|
|
;
|
|
-- insert autre période si date fin overlap inférieur
|
|
INSERT INTO w_histo_ser (nummat, datedeb, datefin, niv1, niv2, niv3, niv4, niv5)
|
|
SELECT
|
|
w_histo_ser_overlap.nummat,
|
|
w_histo_ser_overlap.datefin + '1 day'::interval as datedeb,
|
|
w_histo_ser.datefin,
|
|
w_histo_ser.niv1,
|
|
w_histo_ser.niv2,
|
|
w_histo_ser.niv3,
|
|
w_histo_ser.niv4,
|
|
w_histo_ser.niv5
|
|
FROM w_histo_ser_overlap
|
|
JOIN w_histo_ser ON
|
|
w_histo_ser.nummat = w_histo_ser_overlap.nummat
|
|
AND w_histo_ser_overlap.datefin BETWEEN w_histo_ser.datedeb AND w_histo_ser.datefin
|
|
AND w_histo_ser_overlap.datedeb BETWEEN w_histo_ser.datedeb AND w_histo_ser.datefin
|
|
;
|
|
-- réduit date de fin si date fin overlap supérieure
|
|
UPDATE w_histo_ser
|
|
SET
|
|
datefin = w_histo_ser_overlap.datedeb - '1 day'::interval
|
|
FROM w_histo_ser_overlap
|
|
WHERE 1=1
|
|
AND w_histo_ser_overlap.nummat = w_histo_ser.nummat
|
|
AND w_histo_ser_overlap.datefin BETWEEN w_histo_ser.datedeb AND w_histo_ser.datefin
|
|
AND w_histo_ser_overlap.datedeb BETWEEN w_histo_ser.datedeb AND w_histo_ser.datefin
|
|
;
|
|
|
|
-- codes = code ou numero si pas tous les codes
|
|
UPDATE w_histo_ser
|
|
SET
|
|
niv_cod1 = CASE WHEN empty_codes[1] = 0 THEN niveaux1.niv_code ELSE niveaux1.numero::text END,
|
|
niv_cod2 = CASE WHEN empty_codes[2] = 0 THEN niveaux2.niv_code ELSE niveaux2.numero::text END,
|
|
niv_cod3 = CASE WHEN empty_codes[3] = 0 THEN niveaux3.niv_code ELSE niveaux3.numero::text END,
|
|
niv_cod4 = CASE WHEN empty_codes[4] = 0 THEN niveaux4.niv_code ELSE niveaux4.numero::text END,
|
|
niv_cod5 = CASE WHEN empty_codes[5] = 0 THEN niveaux5.niv_code ELSE niveaux5.numero::text END
|
|
|
|
FROM
|
|
prod_gestor.niveaux1,prod_gestor.niveaux2,prod_gestor.niveaux3,prod_gestor.niveaux4,prod_gestor.niveaux5,
|
|
(
|
|
SELECT ARRAY[
|
|
(SELECT count(*) FROM prod_gestor.niveaux1 WHERE niv_code = '' AND numero != 0),
|
|
(SELECT count(*) FROM prod_gestor.niveaux2 WHERE niv_code = '' AND numero != 0),
|
|
(SELECT count(*) FROM prod_gestor.niveaux3 WHERE niv_code = '' AND numero != 0),
|
|
(SELECT count(*) FROM prod_gestor.niveaux4 WHERE niv_code = '' AND numero != 0),
|
|
(SELECT count(*) FROM prod_gestor.niveaux5 WHERE niv_code = '' AND numero != 0)] AS empty_codes
|
|
) sub
|
|
WHERE 1=1
|
|
AND niv1 = niveaux1.numero
|
|
AND niv2 = niveaux2.numero
|
|
AND niv3 = niveaux3.numero
|
|
AND niv4 = niveaux4.numero
|
|
AND niv5 = niveaux5.numero
|
|
;
|
|
|
|
UPDATE w_histo_ser
|
|
SET niv2 = niv_cod2
|
|
;
|
|
]]></sqlcmd>
|
|
</NODE>
|
|
|
|
<NODE label="Import planning">
|
|
<sqlcmd><![CDATA[
|
|
|
|
-- Maintenance table temporaire prod_gestor_compteurj.
|
|
VACUUM ANALYSE prod_gestor_compteurj
|
|
;
|
|
|
|
CREATE INDEX prod_gestor_compteurj_ik_nummat ON prod_gestor_compteurj USING btree (nummat)
|
|
;
|
|
|
|
-- Alimenter le champ prod_gestor_compteurj.salarie_corr. cas avec SHS
|
|
UPDATE prod_gestor_compteurj SET
|
|
salarie_corr = matricule
|
|
FROM prod_gestor_pers
|
|
WHERE prod_gestor_pers.nummat = prod_gestor_compteurj.nummat
|
|
;
|
|
|
|
UPDATE prod_gestor_absence SET
|
|
salarie_corr = matricule
|
|
FROM prod_gestor_pers
|
|
WHERE prod_gestor_pers.nummat = prod_gestor_absence.nummat
|
|
;
|
|
|
|
|
|
|
|
-- 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,
|
|
right(t_etablissements.code,3) as etablissement_planning_code,
|
|
''::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, cela pourrait être le cas dans gestor et 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
|
|
ORDER BY 1,2,3
|
|
;
|
|
|
|
|
|
-- 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)
|
|
;
|
|
|
|
DROP SEQUENCE IF EXISTS w_compteurj_seq
|
|
;
|
|
|
|
CREATE TEMP SEQUENCE w_compteurj_seq
|
|
;
|
|
|
|
DROP TABLE IF EXISTS w_compteurj
|
|
;
|
|
|
|
CREATE TEMP TABLE w_compteurj AS
|
|
SELECT
|
|
nextval('w_compteurj_seq') as compteurj_id,
|
|
prod_gestor_compteurj.salarie_corr,
|
|
null::bigint AS salarie_id,
|
|
null::bigint AS contrat_id,
|
|
null::bigint AS contrat_mois_id,
|
|
date(datej) AS date,
|
|
niv5,
|
|
niv2,
|
|
niv3,
|
|
niv4,
|
|
niv2 || '|' || niv3 || '|' || niv4 AS niveaux_code_original,
|
|
niv2 || '|' || niv3 || '|' || niv4 AS service_code_original,
|
|
niv_cod2 AS entets_code,
|
|
''::text AS abs_cod,
|
|
cpt001 AS temps_du_initial,
|
|
cpt003::numeric AS temps_du,
|
|
cpt003::numeric AS temps_valide,
|
|
0::numeric AS temps_absence
|
|
FROM prod_gestor_compteurj-- where (1!=1 OR cpt001 != 0 OR cpt003 != 0 )and datej > '2015-01-01'
|
|
LEFT JOIN w_histo_ser ON w_histo_ser.nummat = prod_gestor_compteurj.nummat
|
|
AND datej BETWEEN datedeb AND datefin
|
|
WHERE
|
|
(1!=1
|
|
OR cpt001 != 0
|
|
OR cpt003 != 0
|
|
)
|
|
and datej > '2015-01-01'
|
|
;
|
|
|
|
INSERT INTO w_compteurj
|
|
SELECT
|
|
nextval('w_compteurj_seq') as compteurj_id,
|
|
prod_gestor_absence.salarie_corr,
|
|
0::bigint AS salarie_id,
|
|
null::bigint AS contrat_id,
|
|
null::bigint AS contrat_mois_id,
|
|
date(dateval) AS date,
|
|
niv5,
|
|
niv2,
|
|
niv3,
|
|
niv4,
|
|
niv2 || '|' || niv3 || '|' || niv4 AS niveaux_code_original,
|
|
niv2 || '|' || niv3 || '|' || niv4 AS service_code_original,
|
|
niv_cod2 AS entets_code,
|
|
code AS abs_cod,
|
|
0 AS temps_du_initial,
|
|
duree::numeric AS temps_du,
|
|
0 AS temps_valide,
|
|
duree::numeric AS temps_absence
|
|
FROM prod_gestor_absence
|
|
LEFT JOIN w_histo_ser ON w_histo_ser.nummat = prod_gestor_absence.nummat
|
|
AND dateval BETWEEN w_histo_ser.datedeb AND w_histo_ser.datefin
|
|
WHERE duree != 0
|
|
and dateval > '2015-01-01'
|
|
;
|
|
|
|
-- ajout de la structure du salarie si elle n'est pas trouvé dans l'historique
|
|
UPDATE w_compteurj
|
|
SET
|
|
service_code_original = niv_code||'|'||prod_gestor_pers.niv3||'|'||prod_gestor_pers.niv4,
|
|
entets_code = niv_code,
|
|
niv2 = niv_code,
|
|
niv3 = prod_gestor_pers.niv3,
|
|
niv4 = prod_gestor_pers.niv4,
|
|
niv5 = prod_gestor_pers.niv5
|
|
FROM prod_gestor_pers
|
|
JOIN prod_gestor.niveaux2 ON prod_gestor_pers.niv2 = numero
|
|
WHERE 1=1
|
|
AND prod_gestor_pers.matricule = w_compteurj.salarie_corr
|
|
AND entets_code IS NULL
|
|
;
|
|
|
|
UPDATE w_compteurj
|
|
SET
|
|
salarie_id = w_sal_pla.salarie_id
|
|
FROM
|
|
w_sal_pla
|
|
WHERE 1=1
|
|
AND UPPER(w_sal_pla.salarie_corr) = UPPER(w_compteurj.salarie_corr)
|
|
AND entets_code = etablissement_planning_code
|
|
;
|
|
|
|
VACUUM ANALYSE w_compteurj
|
|
;
|
|
|
|
-- 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
|
|
compteurj_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_compteurj
|
|
join rh.p_contrats_mois on 1=1
|
|
and p_contrats_mois.salarie_id = w_compteurj.salarie_id
|
|
and w_compteurj.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_compteurj.contrat_id is null
|
|
OR w_compteurj.contrat_mois_id is null
|
|
group by 1)
|
|
UPDATE w_compteurj SET
|
|
contrat_id = w_asso.contrat_id,
|
|
contrat_mois_id = w_asso.contrat_mois_id
|
|
FROM w_asso
|
|
WHERE w_compteurj.compteurj_id = w_asso.compteurj_id
|
|
;
|
|
|
|
with w_asso as (
|
|
select
|
|
compteurj_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_compteurj
|
|
join rh.p_contrats_mois on 1=1
|
|
and p_contrats_mois.salarie_id = w_compteurj.salarie_id
|
|
and p_contrats_mois.date_debut > w_compteurj.date -- Sélection des contrats APRES heures planning.
|
|
where 1!=1
|
|
OR w_compteurj.contrat_id is null
|
|
OR w_compteurj.contrat_mois_id is null
|
|
group by 1)
|
|
UPDATE w_compteurj SET
|
|
contrat_id = w_asso.contrat_id,
|
|
contrat_mois_id = w_asso.contrat_mois_id
|
|
FROM w_asso
|
|
WHERE w_compteurj.compteurj_id = w_asso.compteurj_id
|
|
;
|
|
|
|
with w_asso as (
|
|
select
|
|
compteurj_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_compteurj
|
|
join rh.p_contrats_mois on 1=1
|
|
and p_contrats_mois.salarie_id = w_compteurj.salarie_id
|
|
and p_contrats_mois.date_debut < w_compteurj.date -- Sélection des contrats AVANT heures planning.
|
|
where 1!=1
|
|
OR w_compteurj.contrat_id is null
|
|
OR w_compteurj.contrat_mois_id is null
|
|
group by 1)
|
|
UPDATE w_compteurj SET
|
|
contrat_id = w_asso.contrat_id,
|
|
contrat_mois_id = w_asso.contrat_mois_id
|
|
FROM w_asso
|
|
WHERE w_compteurj.compteurj_id = w_asso.compteurj_id
|
|
;
|
|
|
|
DELETE FROM w_compteurj
|
|
where 1=1
|
|
and (1!=1
|
|
or contrat_mois_id is null
|
|
or contrat_id is null)
|
|
;
|
|
|
|
-- Création d'index.
|
|
CREATE INDEX w_compteurj_i_contrat_id ON w_compteurj USING btree (contrat_id)
|
|
;
|
|
CREATE INDEX w_compteurj_i_contrat_mois_id ON w_compteurj USING btree (contrat_mois_id)
|
|
;
|
|
CREATE INDEX w_compteurj_i_date ON w_compteurj USING btree (date)
|
|
;
|
|
CREATE INDEX w_compteurj_i_salarie_id ON w_compteurj USING btree (salarie_id)
|
|
;
|
|
|
|
DROP TABLE IF EXISTS w_ser;
|
|
CREATE TEMP TABLE w_ser AS
|
|
SELECT
|
|
service_code_original,
|
|
niv2,
|
|
niv3,
|
|
niv4,
|
|
entets_code as niv_cod2,
|
|
''::text AS niv_cod3,
|
|
''::text AS niv_cod4,
|
|
''::text AS texte,
|
|
''::text AS texte_court
|
|
FROM
|
|
w_compteurj
|
|
GROUP BY 1,2,3,4,5
|
|
;
|
|
|
|
UPDATE w_ser SET
|
|
niv_cod3 = CASE WHEN empty_codes[1] = 0 THEN niveaux3.niv_code ELSE niveaux3.numero::text END,
|
|
niv_cod4 = CASE WHEN empty_codes[2] = 0 THEN niveaux4.niv_code ELSE niveaux4.numero::text END
|
|
FROM
|
|
prod_gestor.niveaux3,prod_gestor.niveaux4,
|
|
(
|
|
SELECT ARRAY[
|
|
(SELECT count(*) FROM prod_gestor.niveaux3 WHERE (niv_code = '' OR niv_code IS NULL) AND numero != 0),
|
|
(SELECT count(*) FROM prod_gestor.niveaux4 WHERE (niv_code = '' OR niv_code IS NULL) AND numero != 0)] AS empty_codes
|
|
) sub
|
|
WHERE 1=1
|
|
AND niv3 = niveaux3.numero
|
|
AND niv4 = niveaux4.numero
|
|
;
|
|
|
|
UPDATE w_ser SET
|
|
texte = COALESCE(niveaux2.libelle, niv_cod2)|| ' - '||COALESCE(niveaux3.libelle, niv_cod3) || ' - '||COALESCE(niveaux4.libelle, niv_cod4),
|
|
texte_court = substr(COALESCE(niveaux2.libelle, niv_cod2)|| ' - '||COALESCE(niveaux3.libelle, niv_cod3) || ' - '||COALESCE(niveaux4.libelle, niv_cod4),1,50)
|
|
FROM
|
|
prod_gestor.niveaux2,prod_gestor.niveaux3,prod_gestor.niveaux4
|
|
WHERE 1=1
|
|
AND niv2 = niveaux2.niv_code
|
|
AND niv3 = niveaux3.numero
|
|
AND niv4 = niveaux4.numero
|
|
;
|
|
|
|
-- 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
|
|
service_code_original,
|
|
niv_cod2||'|'||niv_cod3||'|'||niv_cod4,
|
|
texte,
|
|
texte_court,
|
|
0 as service_id
|
|
FROM w_ser
|
|
WHERE service_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 niveauxx du Planning.
|
|
INSERT INTO rh.t_planning_niveau(code_original, code, texte, texte_court)
|
|
SELECT
|
|
service_code_original,
|
|
niv_cod2||'|'||niv_cod3||'|'||niv_cod4,
|
|
texte,
|
|
texte_court
|
|
FROM w_ser
|
|
WHERE service_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
|
|
numero,
|
|
numero,
|
|
libelle,
|
|
substr(libelle,1,50)
|
|
FROM prod_gestor.niveaux5 AS poste
|
|
WHERE 1=1
|
|
AND numero IN (SELECT niv5 FROM w_compteurj)
|
|
AND numero 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
|
|
numero,
|
|
code,
|
|
libelle,
|
|
substr(libelle,1,50)
|
|
FROM prod_gestor.codeevt AS absence
|
|
WHERE 1=1
|
|
AND code IN (SELECT abs_cod FROM w_compteurj)
|
|
AND numero NOT IN (SELECT code_original FROM rh.t_planning_type_absence WHERE code_original IS NOT NULL)
|
|
GROUP BY 1,2,3,4
|
|
;
|
|
|
|
-- 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
|
|
;
|
|
|
|
-- 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(w_compteurj.date, 'IYYYIW'::text)::numeric AS semaine,
|
|
to_char(w_compteurj.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_du,
|
|
temps_du_initial::numeric,
|
|
temps_valide,
|
|
temps_absence
|
|
FROM w_compteurj
|
|
LEFT JOIN rh.t_planning_niveau ON t_planning_niveau.code_original = w_compteurj.niveaux_code_original
|
|
LEFT JOIN rh.t_planning_service ON t_planning_service.code_original = w_compteurj.service_code_original
|
|
LEFT JOIN rh.t_planning_qualification ON t_planning_qualification.code_original = w_compteurj.niv5
|
|
LEFT JOIN rh.t_planning_type_absence ON t_planning_type_absence.code = w_compteurj.abs_cod
|
|
LEFT JOIN w_entets ON w_entets.entets_code = w_compteurj.entets_code
|
|
;
|
|
|
|
|
|
VACUUM ANALYSE rh.p_planning_mouvement
|
|
;
|
|
|
|
]]></sqlcmd>
|
|
</NODE>
|
|
</NODE>
|
|
<NODE name="POST" type="common" />
|
|
</ROOT>
|