w_cycle.id
order by overlap.utilisateur_id, overlap.date_debut
;
-- maj fin de période si overlap
UPDATE w_cycle
SET
date_fin_cor = sub.date_debut - '1 day'::interval
FROM (SELECT cycle_ref, min(date_debut) AS date_debut FROM w_cycle_overlap GROUP BY 1) sub
WHERE cycle_ref = id
;
INSERT INTO w_cycle
SELECT
w_cycle.id,
w_cycle.utilisateur_id,
w_cycle.poste_id,
w_cycle_overlap.date_fin_cor + interval '1 day',
w_cycle.date_fin,
COALESCE(LEAD(w_cycle_overlap.date_debut) OVER (PARTITION BY cycle_ref ORDER BY w_cycle_overlap.date_debut, w_cycle_overlap.id) - interval '1 day',w_cycle.date_fin),
w_cycle.cycle_id_remplacant,
w_cycle.rh_salarie_societe_id,
w_cycle.commentaire_arret
FROM w_cycle
join w_cycle_overlap on cycle_ref = w_cycle.id order by w_cycle.utilisateur_id ,w_cycle.date_debut, w_cycle_overlap.id;
DELETE FROM w_cycle where date_fin_cor < date_debut;
CREATE INDEX w_cycle_i ON w_cycle USING btree (id);
CREATE INDEX w_cycle_i2 ON w_cycle USING btree (poste_id);
--maj des matricule planning si non renseignés
UPDATE rh.p_salaries
SET matricule_planning = matricule
WHERE matricule_planning = ''
;
-- insertion des matricule non présents ou présent sans la bonne personne
INSERT INTO rh.p_salaries(
finess,
nom,
prenom,
sexe,
matricule,
matricule_planning,
code,
code_original,
entreprise_id
)
SELECT
'Planning' AS finess,
base.cti_soundex_nom((MAX(ARRAY[utilisateur.id::text, utilisateur.nom::text]))[2]),
base.cti_soundex_prenom((MAX(ARRAY[utilisateur.id::text, utilisateur.prenom::text]))[2]),
CASE WHEN (MAX(ARRAY[utilisateur.id, genre]))[2] NOT IN (1,4) THEN 'F' ELSE 'M' END,
'PLA_' || utilisateur.matricule,
utilisateur.matricule AS matricule_planning,
'PLA_' || utilisateur.matricule,
'PLA_' || utilisateur.matricule,
COALESCE(sub.entreprise_id,0)
FROM prod_expert_sante.utilisateur
LEFT JOIN (SELECT entreprise_id FROM rh.t_etablissements JOIN rh.t_divers ON t_divers.code = 'EXPERT_SOCIETE_DEFAULT' AND valeur = planning_code) sub ON 1=1
LEFT JOIN rh.p_salaries ON p_salaries.matricule_planning = utilisateur.matricule
WHERE utilisateur.matricule != ''
AND utilisateur.id IN (SELECT utilisateur_id FROM w_cycle)
AND 'PLA_' || utilisateur.matricule NOT IN (SELECT code_original FROM rh.p_salaries)
GROUP BY 5,6,7,8,9
HAVING MAX(p_salaries.oid) IS NULL OR (
base.cti_soundex_nom((MAX(ARRAY[utilisateur.id::text, utilisateur.nom::text]))[2]) != base.cti_soundex_nom(upper(MAX(p_salaries.nom))) AND
base.cti_soundex_prenom((MAX(ARRAY[utilisateur.id::text, utilisateur.prenom::text]))[2]) != base.cti_soundex_prenom(upper(MAX(p_salaries.prenom)))
)
ORDER BY 5;
-- maj des anciens matricule planning plus utilisés (matricule sans PLA)
UPDATE rh.p_salaries
SET matricule_planning = 'OLD_' || p_salaries.matricule_planning
FROM (
SELECT matricule_planning, MAX(CASE WHEN matricule NOT LIKE 'PLA_%' THEN oid ELSE 0 END) as salarie_id
FROM rh.p_salaries
GROUP BY 1 HAVING count(*) > 1
) sub
WHERE oid = salarie_id
AND p_salaries.matricule_planning NOT LIKE 'OLD_%'
;
-- 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_planning AS 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 AND t_etablissements.planning_code != ''
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
;
-- INSERT INTO rh.p_salaries (code, code_original, nom)
-- lorsque nom ne correspond pas, changer le matricule
--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_plan_base;
CREATE TEMP TABLE w_plan_base AS
SELECT
w_cycle.id,
COALESCE(NULLIF(salarie_societe.matricule,''),utilisateur.matricule) as matricule,
rh_societe_id,
w_cycle.utilisateur_id,
w_cycle.date_debut,
w_cycle.date_fin,
commentaire_arret,
courant.date,
courant.date as date_orig,
poste_id,
profession_rh_id,
etage_id,
rh_salarie_societe_id,
type_poste.code,
CASE WHEN heure_debut != '' THEN left(heure_debut,2)::numeric + right(heure_debut,2)::numeric / 60 ELSE 0 END AS heure_debut,
CASE WHEN heure_fin != '' THEN left(heure_fin,2)::numeric + right(heure_fin,2)::numeric / 60 ELSE 0 END AS heure_fin,
left(temps_travail,2)::numeric + right(temps_travail,2)::numeric / 60 as temps_travail,
temps_pause,
impacte_compteur_nuit,
impacte_compteur_heures_ferie,
impacte_totaux_planning,
roulement.renfort as roulement_renfort,
poste.renfort as poste_renfort,
cycle_id_remplacant,
type_poste.id AS type_poste_id,
rank() OVER (PARTITION BY w_cycle.utilisateur_id, courant.date ORDER BY w_cycle.id) as rank,
last_value(w_cycle.id) OVER (PARTITION BY w_cycle.utilisateur_id, courant.date) as last
FROM w_cycle
JOIN prod_expert_sante.utilisateur ON utilisateur_id = utilisateur.id
left join prod_expert_sante.salarie_societe on rh_salarie_societe_id = salarie_societe.id
join base.p_calendrier courant on courant.date between date_debut AND COALESCE(date_fin_cor, now())
join prod_expert_sante.poste on poste_id = poste.id
join base.p_calendrier debut on debut.date = poste.date_debut
join base.v_calendrier_indicateurs_1 ON courant.date = v_calendrier_indicateurs_1.date
join prod_expert_sante.roulement on roulement_id = roulement.id
join prod_expert_sante.modele_roulement on poste.roulement_id = modele_roulement.roulement_id
AND num_jour = courant.jour_semaine
AND num_semaine = 1 + (debut_semaine - 1 + courant.iso_semaine - debut.iso_semaine + 52 * (date_part('year',courant.date)::numeric - date_part('year', debut.date)::numeric))%nb_semaines
left join prod_expert_sante.type_poste on (type_poste.id = modele_roulement.type_poste_id and (nb_jour_ouvre = 1 or type_poste_jf = 0)) or (nb_jour_ouvre = 0 AND type_poste_jf != 0 AND type_poste_jf = type_poste.id)
WHERE courant.date > '[ENV_PLANNING_DATEDEBUT]'
;
CREATE INDEX w_plan_base_mat ON w_plan_base USING btree (matricule);
-- croisement avec les contrats et les personnes
DROP SEQUENCE IF EXISTS w_cptres1_seq
;
CREATE TEMP SEQUENCE w_cptres1_seq
;
DROP TABLE IF EXISTS w_cptres1
;
-- temps travail = temps du initial
CREATE TEMP TABLE w_cptres1 AS
SELECT
nextval('w_cptres1_seq') as cptres1_id,
w_plan_base.utilisateur_id,
w_plan_base.matricule,
salarie_id,
null::bigint AS contrat_id,
null::bigint AS contrat_mois_id,
date,
date_orig,
temps_travail AS temps_orig,
profession_rh_id,
etage_id,
rh_societe_id,
''::text AS motif_absence_id,
temps_travail::numeric AS temps_du_initial,
0::numeric AS temps_du,
0::numeric AS temps_valide,
0::numeric AS temps_absence,
type_poste_id
FROM w_plan_base
LEFT JOIN prod_expert_sante.absence_salarie ON w_plan_base.id = absence_salarie.cycle_id AND date_orig BETWEEN absence_salarie.date_debut AND absence_salarie.date_fin
LEFT JOIN prod_expert_sante.motif_absence ON motif_absence.id = motif_absence_id
JOIN w_sal_pla ON w_sal_pla.matricule = w_plan_base.matricule
WHERE 1=1
AND COALESCE(absence_non_reelle,0) != 1
AND w_plan_base.id = last
ORDER BY 2,7
;
-- absences (note dans table pas d'heure de debut ni de fin)
INSERT INTO w_cptres1
SELECT
nextval('w_cptres1_seq') as cptres1_id,
w_plan_base.utilisateur_id,
w_plan_base.matricule,
salarie_id,
null::bigint AS contrat_id,
null::bigint AS contrat_mois_id,
date,
date_orig,
temps_travail AS temps_orig,
profession_rh_id,
etage_id,
rh_societe_id,
motif_absence_id,
0 AS temps_du_initial,
CASE WHEN absence_non_reelle = 0 THEN temps_travail ELSE 0 END AS temps_du,
0 AS temps_valide,
CASE WHEN absence_non_reelle = 0 THEN temps_travail ELSE 0 END AS temps_absence,
type_poste_id
FROM w_plan_base
JOIN prod_expert_sante.absence_salarie ON w_plan_base.id = absence_salarie.cycle_id AND date_orig BETWEEN absence_salarie.date_debut AND absence_salarie.date_fin
JOIN prod_expert_sante.motif_absence ON motif_absence.id = motif_absence_id
JOIN w_sal_pla ON w_sal_pla.matricule = w_plan_base.matricule
WHERE 1=1 AND
validee = 1
ORDER BY 2,7
;
-- pas d'absence => valide sur dernier cycle prevu
INSERT INTO w_cptres1
SELECT
nextval('w_cptres1_seq') as cptres1_id,
w_plan_base.utilisateur_id,
w_plan_base.matricule,
salarie_id,
null::bigint AS contrat_id,
null::bigint AS contrat_mois_id,
date,
date_orig,
temps_travail AS temps_orig,
profession_rh_id,
etage_id,
rh_societe_id,
motif_absence_id,
0 AS temps_du_initial,
temps_travail AS temps_du,
temps_travail AS temps_valide,
0 AS temps_absence,
type_poste_id
FROM w_plan_base
LEFT JOIN prod_expert_sante.absence_salarie ON w_plan_base.id = absence_salarie.cycle_id AND date_orig BETWEEN absence_salarie.date_debut AND absence_salarie.date_fin
JOIN w_sal_pla ON w_sal_pla.matricule = w_plan_base.matricule
WHERE 1=1
AND absence_salarie.id IS NULL
AND w_plan_base.id = last
--AND validee = 1
ORDER BY 2,7
;
-- heures supplémentaires - comment utiliser type_heure_supplemntaire_id ?
INSERT INTO w_cptres1
SELECT
nextval('w_cptres1_seq') as cptres1_id,
heure_supplementaire.utilisateur_id,
utilisateur.matricule,
salarie_id,
null::bigint AS contrat_id,
null::bigint AS contrat_mois_id,
jour,
jour AS date_orig,
0 AS temps_orig,
profession_rh_id,
etage_id,
null,
-1,
0 AS temps_du_initial,
CASE WHEN sens = '+' then 1 ELSE -1 END * (left(heure,2)::numeric + right(heure,2)::numeric / 60) AS temps_du,
CASE WHEN sens = '+' then 1 ELSE -1 END * (left(heure,2)::numeric + right(heure,2)::numeric / 60) AS temps_valide,
0 AS temps_absence,
0 as type_poste_id
FROM prod_expert_sante.heure_supplementaire
--LEFT JOIN prod_expert_sante.salarie_societe_dis on heure_supplementaire.utilisateur_id = salarie_societe_dis.utilisateur_id AND visible = 1
JOIN prod_expert_sante.utilisateur ON heure_supplementaire.utilisateur_id = utilisateur.id
JOIN prod_expert_sante.poste ON poste_id = poste.id
JOIN w_sal_pla ON w_sal_pla.matricule = utilisateur.matricule
LEFt JOIN rh.t_divers ON code = 'EXPERT_SOCIETE_DEFAULT'
WHERE jour > '[ENV_PLANNING_DATEDEBUT]'
--AND payable = 1
;
/* UPDATE w_cptres1
SET rh_societe_id = salarie_societe_dis.rh_societe_id
FROM prod_expert_sante.salarie_societe_dis
WHERE salarie_societe_dis.utilisateur_id = w_cptres1.utilisateur_id
AND w_cptres1.rh_societe_id IS NULL
;*/
SELECT base.cti_execute('INSERT INTO rh.t_divers (code, valeur, description)
VALUES
(''EXPERT_SOCIETE_DEFAULT'',''0'',''id societe expert à affecter aux salaries par defaut'')',1)
WHERE (SELECT count(*) FROM rh.t_divers WHERE code = 'EXPERT_SOCIETE_DEFAULT') = 0
;
UPDATE w_cptres1
SET rh_societe_id = valeur::int
FROM rh.t_divers
WHERE t_divers.code = 'EXPERT_SOCIETE_DEFAULT'
AND rh_societe_id IS NULL
;
DELETE FROM w_cptres1 WHERE temps_du_initial = 0 AND temps_valide = 0 AND temps_absence = 0 AND temps_du = 0;
CREATE INDEX w_cptres1_i_date ON w_cptres1 USING btree (date_orig)
;
CREATE INDEX w_cptres1_i_salarie_id ON w_cptres1 USING btree (salarie_id)
;
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_orig 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_orig -- 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
AND w_cptres1.contrat_mois_id is null
;
/*
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_orig -- 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
AND w_cptres1.contrat_mois_id is null
;
*/
-- 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)
;
-- 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)
WITH services AS (
SELECT
id,
id::text as code,
nom,
etage_id
FROM prod_expert_sante.service
WHERE id != 0
GROUP BY 1,2,3,4
UNION ALL
SELECT
'0' AS id,
'NR' AS code,
'Non renseigné' as texte,
null as etage_id
)
SELECT id , id, nom, LEFT(nom,50), (select oid from rh.t_classes where code = 'PLANIV3') as classe_id
FROM services
WHERE id NOT IN (SELECT code_original FROM rh.t_planning_service WHERE code_original IS NOT NULL)
AND (etage_id IN (SELECT etage_id FROM w_cptres1 GROUP BY 1) OR etage_id IS NULL)
GROUP BY 1,2,3,4
;
INSERT INTO rh.t_planning_niveau(code_original, code, texte, texte_court)
SELECT
code_original,
code,
texte,
left(texte,50)
FROM w_structure
WHERE code_original NOT IN (SELECT code_original FROM rh.t_planning_niveau WHERE code_original IS NOT NULL)
AND split_part(code_original,'|',3) IN (SELECT etage_id FROM w_cptres1 GROUP BY 1)
;
-- Màj des Qualifications du Planning. (competence)
INSERT INTO rh.t_planning_qualification(code_original, code, texte, texte_court)
SELECT
ID,
ID,
NOM,
NOM
FROM prod_expert_sante.RH_PROFESSION
WHERE 1=1
AND ID IN (SELECT profession_rh_id FROM w_cptres1)
AND ID NOT IN (SELECT code_original FROM rh.t_planning_qualification WHERE code_original IS NOT NULL)
;
-- Màj des Types d'absences du Planning. (ch)
INSERT INTO rh.t_planning_type_absence(code_original, code, texte, texte_court)
SELECT
id,
code,
nom,
left(nom,50)
FROM prod_expert_sante.motif_absence
WHERE 1=1
AND id IN (SELECT motif_absence_id FROM w_cptres1 GROUP BY 1)
AND id 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
id,
code,
nom,
LEFT(nom,50)
FROM prod_expert_sante.type_poste
WHERE 1=1
AND id IN (SELECT DISTINCT type_poste_id FROM w_cptres1)
AND id NOT IN (SELECT code_original FROM rh.t_planning_code_horaire WHERE code_original IS NOT NULL)
;
-- Création d'une table Entreprise/Etablissement.
DROP TABLE IF EXISTS w_entets
;
CREATE TEMP TABLE w_entets AS
SELECT
ets.oid as etablissement_id,
ent.planning_code||ets.planning_code as entets_code
from rh.t_entreprises as ent
join rh.t_etablissements as ets on ets.entreprise_id = ent.oid
Where 1=1
and ent.oid != 0
and ets.oid != 0
;
-- Alimentation de la table de mouvement.
-- Alimentation de la table de mouvement.
TRUNCATE rh.p_planning_mouvement
;
INSERT INTO rh.p_planning_mouvement(
salarie_id,
contrat_id,
contrat_mois_id,
date,
semaine,
mois,
etablissement_id, -- @todo à renseigner en fonction du paramétrage dans t_divers.
service_id,
qualification_id,
type_absence_id,
niveau_id,
temps_du,
temps_du_initial,
temps_valide,
temps_absence,
code_horaire_id)
SELECT
salarie_id,
contrat_id,
contrat_mois_id,
date_orig,
to_char(date_orig, 'IYYYIW'::text)::numeric AS semaine,
to_char(date_orig, 'YYYYMM'::text)::numeric AS mois,
coalesce(w_entets.etablissement_id, 0) as etablissement_id,
coalesce(t_planning_service.oid, 0) AS service_id,
coalesce(t_planning_qualification.oid, 0) AS qualification_id,
coalesce(t_planning_type_absence.oid, 0) AS type_absence_id,
coalesce(t_planning_niveau.oid, 0) as niveau_id,
temps_valide + temps_absence,
temps_du_initial,
temps_valide,
temps_absence,
COALESCE(t_planning_code_horaire.oid,0)
FROM w_cptres1
LEFT JOIN rh.t_planning_service ON t_planning_service.code_original = w_cptres1.etage_id
LEFT JOIN rh.t_planning_qualification ON t_planning_qualification.code_original = w_cptres1.profession_rh_id
LEFT JOIN rh.t_planning_type_absence ON t_planning_type_absence.code_original = w_cptres1.motif_absence_id
LEFT JOIN w_entets ON w_entets.entets_code = 1 -- w_cptres1.entets_code
LEFT JOIN rh.t_planning_niveau ON split_part(t_planning_niveau.code_original,'|',3) = w_cptres1.etage_id AND split_part(t_planning_niveau.code_original,'|',1) = w_cptres1.rh_societe_id
LEFT JOIN rh.t_planning_code_horaire ON t_planning_code_horaire.code_original = w_cptres1.type_poste_id
LEFT JOIN rh.t_divers VENTIL_JOUR ON VENTIL_JOUR.code = 'VENTIL_JOUR'
;
VACUUM ANALYSE rh.p_planning_mouvement
;
]]>