0
FROM information_schema.tables
WHERE 1=1
AND table_schema = 'prod_octime'
;
]]>
0
FROM information_schema.tables
WHERE 1=1
AND table_schema = 'prod_octime2'
AND table_name LIKE 'cptres1%'
;
]]>
0
FROM information_schema.tables
WHERE 1=1
AND table_schema = 'prod_octime_saas'
AND table_name LIKE 'cptres1%'
;
]]>
0
FROM information_schema.tables
WHERE 1=1
AND table_schema = 'prod_octime'
;
]]>
0
FROM information_schema.tables
WHERE 1=1
AND table_schema = 'prod_octime2'
AND table_name LIKE 'cptres1%'
;
]]>
0
FROM information_schema.tables
WHERE 1=1
AND table_schema = 'prod_octime_saas'
AND table_name LIKE 'cptres1%'
;
]]>
0 -- il faut que le matricule de paie Octime contienne INT.
ELSE true END
GROUP BY 1,2,3,4,5,6,7,8,9,10,11,12,13, 15,16,17,18,19,20,21,22,23,24,25,26
;
-- Alimenter le champ prod_octime_cptres1.salarie_corr pour les intérim qui n'auraient pas été préfixés par le code ent/ets comme les matricules salariés.
UPDATE prod_octime_cptres1 SET
salarie_corr = (SELECT trim(valeur) FROM rh.t_divers WHERE code = 'OCTIME_INTERIM_PREFIXE')||coalesce(nullif(pers.pers_matp, ''), pers.pers_mat)
FROM prod_octime_pers AS pers, w_salaries
WHERE 1=1
AND prod_octime_cptres1.pers_mat = pers.pers_mat
AND prod_octime_cptres1.pers_mat = w_salaries.pers_mat -- uniquement les intérimaires.
AND salarie_corr = '' -- uniquement les données pas déjà mis à jour.
AND (SELECT trim(valeur) != '' FROM rh.t_divers WHERE code = 'OCTIME_INTERIM_PREFIXE') -- uniquement si un paramétrage a été fait.
;
]]>
ADP.
WHEN 11 THEN -- Cas 11 - NIR. avec gestion de l'interim sans NIR
CASE WHEN cont_cod = (select valeur from rh.t_divers where code = 'INTERIM_CNT_CODE')
THEN coalesce(nullif(pers.pers_matp, ''), pers.pers_mat)
ELSE pers.pers_nsecu
END
ELSE coalesce(nullif(pers.pers_matp, ''), pers.pers_mat) -- Par défaut.
END
FROM prod_octime_pers AS pers
WHERE 1=1
AND prod_octime_cptres1.pers_mat = pers.pers_mat
AND salarie_corr = '' -- uniquement les données pas déjà mis à jour (cf. interim plus haut).
;
-- 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.nir,
p_salaries.matricule,
p_salaries.date_debut as sal_date_debut, -- utilisé lorsque
p_salaries.date_fin as sal_date_fin,
p_salaries.matricule_planning as matricule_paie_planning, -- Matricule planning saisi dans la paie.
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
rank() over (partition by p_salaries.nir order by p_salaries.date_fin desc) as rang, -- Lorsque stratégie basée sur le NIR, permet d'identifier les doublons.
''::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 Octime 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
JOIN (SELECT valeur FROM rh.t_divers WHERE code = 'OCTIME_ETS_ID') AS octime_ets_id ON 1=1
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.
AND CASE WHEN octime_ets_id.valeur = 0 THEN nullif(trim(t_etablissements.planning_code), '') IS NOT NULL ELSE TRUE END
GROUP BY 1,2,3,4,5,6,7,8,9,10,11,12,13,14,15
ORDER BY 1,2,3
;
-- Stratégie basée sur le NIR : suppression des salariés en doublons.
DELETE FROM w_sal_pla
WHERE 1=1
and (SELECT valeur FROM rh.t_divers WHERE code = 'OCTIME_SALARIE') = 11
and rang > 1
;
-- Gestion des salariés fusionnés.
INSERT INTO w_sal_pla
SELECT
w_sal_pla.salarie_id,
p_salaries.nir,
p_salaries.matricule,
w_sal_pla.sal_date_debut,
w_sal_pla.sal_date_fin,
p_salaries.matricule_planning as matricule_paie_planning,
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,
1 as rang,
''::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 =
CASE (SELECT valeur FROM rh.t_divers WHERE code = 'OCTIME_SALARIE')
WHEN 1 THEN matricule_trim
WHEN 2 THEN matricule_planning
WHEN 5 THEN matricule_planning_conso
WHEN 3 THEN etablissement_planning_code||'|'||matricule
-- Le cas 6 nécessite le paramétrage du planning_code pour l'établissement et éventuellement l'entreprise.
-- Pour le cas "010000002631K", on peut paramétrer ent. à "01000" et ets. à "000".
WHEN 6 THEN entreprise_planning_code||etablissement_planning_code||matricule
-- Le cas 9 utilise la matricule planning saisi dans la paie.
WHEN 9 THEN matricule_paie_planning
WHEN 10 THEN case when substr(matricule, 1 , 4) = '0000' then (SELECT valeur FROM rh.t_divers WHERE code = 'OCTIME_OLDMAT_PREFIXE')||matricule_trim else matricule end -- Cas 10 - Fusion QuadraRH -> ADP.
WHEN 11 THEN nir -- Cas 11 : NIR
-- Les cas 4, 7 et 8 ne nécessitent pas de transformation du matricule issu de la paie.
ELSE matricule
END
;
-- 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 SEQUENCE IF EXISTS w_cptres1_seq
;
CREATE TEMP SEQUENCE w_cptres1_seq
;
DROP TABLE IF EXISTS w_cptres1
;
CREATE TEMP TABLE w_cptres1 AS
SELECT
nextval('w_cptres1_seq') as cptres1_id,
prod_octime_cptres1.salarie_corr,
w_sal_pla.salarie_id,
null::bigint AS contrat_id,
null::bigint AS contrat_mois_id,
date(cal_dat) AS date,
pos_cod,
niv_cod1,
niv_cod2,
niv_cod3,
niv_cod4,
CASE octime_max_niveau.valeur
WHEN 3 THEN niv_cod1 || '|' || niv_cod2 || '|' || niv_cod3
WHEN 4 THEN niv_cod1 || '|' || niv_cod2 || '|' || niv_cod3 || '|' || niv_cod4
END AS niveau_code_original,
CASE octime_service_id.valeur
WHEN 1 THEN niv_cod1
WHEN 2 THEN niv_cod1 || '|' || niv_cod2
WHEN 3 THEN niv_cod1 || '|' || niv_cod2 || '|' || niv_cod3
WHEN 4 THEN niv_cod1 || '|' || niv_cod2 || '|' || niv_cod3 || '|' || niv_cod4
END AS service_code_original,
CASE octime_ets_id.valeur
WHEN 0 THEN octime_ets_manuel.valeur
WHEN 1 THEN niv_cod1 -- cas AHO
WHEN 2 THEN niv_cod2
WHEN 3 THEN niv_cod3
WHEN 4 THEN CASE WHEN octime_max_niveau.valeur = '3' THEN left(prod_octime_cptres1.pers_mat, -5) ELSE niv_cod4 END -- cas Fondation Hopale avec OCTIME_MAX_NIVEAU positionné par défaut sur 3.
WHEN 9 THEN left(prod_octime_cptres1.pers_mat, -5) -- cas Fondation Hopale
END AS entets_code,
''::text AS abs_cod,
hor_cod, -- code horaire.
cal_val2/60.00 AS temps_du_initial,
cal_val3/60.00 AS temps_du,
CASE tps_valide.valeur WHEN '6' THEN cal_val6 ELSE cal_val5 END/60.00 AS temps_valide,
0::numeric AS temps_absence,
0 AS temps_hs,
0 AS temps_hc
FROM prod_octime_cptres1
JOIN w_sal_pla ON w_sal_pla.salarie_corr = prod_octime_cptres1.salarie_corr
JOIN (SELECT valeur FROM rh.t_divers WHERE code = 'OCTIME_TPS_VALIDE') AS tps_valide ON 1=1
JOIN (SELECT valeur FROM rh.t_divers WHERE code = 'OCTIME_SERVICE_ID') AS octime_service_id ON 1=1
JOIN (SELECT valeur FROM rh.t_divers WHERE code = 'OCTIME_ETS_ID') AS octime_ets_id ON 1=1
JOIN (SELECT valeur FROM rh.t_divers WHERE code = 'OCTIME_ETS_MANUEL') AS octime_ets_manuel ON 1=1
JOIN (SELECT valeur FROM rh.t_divers WHERE code = 'OCTIME_MAX_NIVEAU') AS octime_max_niveau ON 1=1
WHERE 1!=1
OR cal_val2 != 0
OR cal_val3 != 0
OR CASE tps_valide.valeur WHEN '6' THEN cal_val6 ELSE cal_val5 END != 0
;
INSERT INTO w_cptres1
SELECT
nextval('w_cptres1_seq') as cptres1_id,
prod_octime_cptres1.salarie_corr,
w_sal_pla.salarie_id,
null::bigint AS contrat_id,
null::bigint AS contrat_mois_id,
date(cal_dat) AS date,
pos_cod,
niv_cod1,
niv_cod2,
niv_cod3,
niv_cod4,
CASE octime_max_niveau.valeur
WHEN 3 THEN niv_cod1 || '|' || niv_cod2 || '|' || niv_cod3
WHEN 4 THEN niv_cod1 || '|' || niv_cod2 || '|' || niv_cod3 || '|' || niv_cod4
END AS niveau_code_original,
CASE octime_service_id.valeur
WHEN 1 THEN niv_cod1
WHEN 2 THEN niv_cod1 || '|' || niv_cod2
WHEN 3 THEN niv_cod1 || '|' || niv_cod2 || '|' || niv_cod3
WHEN 4 THEN niv_cod1 || '|' || niv_cod2 || '|' || niv_cod3 || '|' || niv_cod4
END AS service_code_original,
CASE octime_ets_id.valeur
WHEN 0 THEN octime_ets_manuel.valeur
WHEN 1 THEN niv_cod1 -- cas AHO
WHEN 2 THEN niv_cod2
WHEN 3 THEN niv_cod3
WHEN 4 THEN CASE WHEN octime_max_niveau.valeur = '3' THEN left(prod_octime_cptres1.pers_mat, -5) ELSE niv_cod4 END -- cas Fondation Hopale avec OCTIME_MAX_NIVEAU positionné par défaut sur 3.
WHEN 9 THEN left(prod_octime_cptres1.pers_mat, -5) -- cas Fondation Hopale
END AS entets_code,
cal_val24 AS abs_cod,
hor_cod, -- code horaire.
0 AS temps_du,
0 AS temps_du_initial,
0 AS temps_valide,
cal_val21/60.00 AS temps_absence,
0 AS temps_hs,
0 AS temps_hc
FROM prod_octime_cptres1
JOIN w_sal_pla ON w_sal_pla.salarie_corr = prod_octime_cptres1.salarie_corr
JOIN (SELECT valeur FROM rh.t_divers WHERE code = 'OCTIME_SERVICE_ID') AS octime_service_id ON 1=1
JOIN (SELECT valeur FROM rh.t_divers WHERE code = 'OCTIME_ETS_ID') AS octime_ets_id ON 1=1
JOIN (SELECT valeur FROM rh.t_divers WHERE code = 'OCTIME_ETS_MANUEL') AS octime_ets_manuel ON 1=1
JOIN (SELECT valeur FROM rh.t_divers WHERE code = 'OCTIME_MAX_NIVEAU') AS octime_max_niveau ON 1=1
WHERE cal_val21 != 0
;
INSERT INTO w_cptres1
SELECT
nextval('w_cptres1_seq') as cptres1_id,
prod_octime_cptres1.salarie_corr,
w_sal_pla.salarie_id,
null::bigint AS contrat_id,
null::bigint AS contrat_mois_id,
date(cal_dat) AS date,
pos_cod,
niv_cod1,
niv_cod2,
niv_cod3,
niv_cod4,
CASE octime_max_niveau.valeur
WHEN 3 THEN niv_cod1 || '|' || niv_cod2 || '|' || niv_cod3
WHEN 4 THEN niv_cod1 || '|' || niv_cod2 || '|' || niv_cod3 || '|' || niv_cod4
END AS niveau_code_original,
CASE octime_service_id.valeur
WHEN 1 THEN niv_cod1
WHEN 2 THEN niv_cod1 || '|' || niv_cod2
WHEN 3 THEN niv_cod1 || '|' || niv_cod2 || '|' || niv_cod3
WHEN 4 THEN niv_cod1 || '|' || niv_cod2 || '|' || niv_cod3 || '|' || niv_cod4
END AS service_code_original,
CASE octime_ets_id.valeur
WHEN 0 THEN octime_ets_manuel.valeur
WHEN 1 THEN niv_cod1 -- cas AHO
WHEN 2 THEN niv_cod2
WHEN 3 THEN niv_cod3
WHEN 4 THEN CASE WHEN octime_max_niveau.valeur = '3' THEN left(prod_octime_cptres1.pers_mat, -5) ELSE niv_cod4 END -- cas Fondation Hopale avec OCTIME_MAX_NIVEAU positionné par défaut sur 3.
WHEN 9 THEN left(prod_octime_cptres1.pers_mat, -5) -- cas Fondation Hopale
END AS entets_code,
cal_val25 AS abs_cod,
hor_cod, -- code horaire.
0 AS temps_du,
0 AS temps_du_initial,
0 AS temps_valide,
cal_val22/60.00 AS temps_absence,
0 AS temps_hs,
0 AS temps_hc
FROM prod_octime_cptres1
JOIN w_sal_pla ON w_sal_pla.salarie_corr = prod_octime_cptres1.salarie_corr
JOIN (SELECT valeur FROM rh.t_divers WHERE code = 'OCTIME_SERVICE_ID') AS octime_service_id ON 1=1
JOIN (SELECT valeur FROM rh.t_divers WHERE code = 'OCTIME_ETS_ID') AS octime_ets_id ON 1=1
JOIN (SELECT valeur FROM rh.t_divers WHERE code = 'OCTIME_ETS_MANUEL') AS octime_ets_manuel ON 1=1
JOIN (SELECT valeur FROM rh.t_divers WHERE code = 'OCTIME_MAX_NIVEAU') AS octime_max_niveau ON 1=1
WHERE cal_val22 != 0
;
INSERT INTO w_cptres1
SELECT
nextval('w_cptres1_seq') as cptres1_id,
prod_octime_cptres1.salarie_corr,
w_sal_pla.salarie_id,
null::bigint AS contrat_id,
null::bigint AS contrat_mois_id,
date(cal_dat) AS date,
pos_cod,
niv_cod1,
niv_cod2,
niv_cod3,
niv_cod4,
CASE octime_max_niveau.valeur
WHEN 3 THEN niv_cod1 || '|' || niv_cod2 || '|' || niv_cod3
WHEN 4 THEN niv_cod1 || '|' || niv_cod2 || '|' || niv_cod3 || '|' || niv_cod4
END AS niveau_code_original,
CASE octime_service_id.valeur
WHEN 1 THEN niv_cod1
WHEN 2 THEN niv_cod1 || '|' || niv_cod2
WHEN 3 THEN niv_cod1 || '|' || niv_cod2 || '|' || niv_cod3
WHEN 4 THEN niv_cod1 || '|' || niv_cod2 || '|' || niv_cod3 || '|' || niv_cod4
END AS service_code_original,
CASE octime_ets_id.valeur
WHEN 0 THEN octime_ets_manuel.valeur
WHEN 1 THEN niv_cod1 -- cas AHO
WHEN 2 THEN niv_cod2
WHEN 3 THEN niv_cod3
WHEN 4 THEN CASE WHEN octime_max_niveau.valeur = '3' THEN left(prod_octime_cptres1.pers_mat, -5) ELSE niv_cod4 END -- cas Fondation Hopale avec OCTIME_MAX_NIVEAU positionné par défaut sur 3.
WHEN 9 THEN left(prod_octime_cptres1.pers_mat, -5) -- cas Fondation Hopale
END AS entets_code,
cal_val26 AS abs_cod,
hor_cod, -- code horaire.
0 AS temps_du,
0 AS temps_du_initial,
0 AS temps_valide,
cal_val23/60.00 AS temps_absence,
0 AS temps_hs,
0 AS temps_hc
FROM prod_octime_cptres1
JOIN w_sal_pla ON w_sal_pla.salarie_corr = prod_octime_cptres1.salarie_corr
JOIN (SELECT valeur FROM rh.t_divers WHERE code = 'OCTIME_SERVICE_ID') AS octime_service_id ON 1=1
JOIN (SELECT valeur FROM rh.t_divers WHERE code = 'OCTIME_ETS_ID') AS octime_ets_id ON 1=1
JOIN (SELECT valeur FROM rh.t_divers WHERE code = 'OCTIME_ETS_MANUEL') AS octime_ets_manuel ON 1=1
JOIN (SELECT valeur FROM rh.t_divers WHERE code = 'OCTIME_MAX_NIVEAU') AS octime_max_niveau ON 1=1
WHERE cal_val23 != 0
;
INSERT INTO w_cptres1
SELECT
nextval('w_cptres1_seq') as cptres1_id,
prod_octime_cptres1.salarie_corr,
w_sal_pla.salarie_id,
null::bigint AS contrat_id,
null::bigint AS contrat_mois_id,
date(cal_dat) AS date,
pos_cod,
niv_cod1,
niv_cod2,
niv_cod3,
niv_cod4,
CASE octime_max_niveau.valeur
WHEN 3 THEN niv_cod1 || '|' || niv_cod2 || '|' || niv_cod3
WHEN 4 THEN niv_cod1 || '|' || niv_cod2 || '|' || niv_cod3 || '|' || niv_cod4
END AS niveau_code_original,
CASE octime_service_id.valeur
WHEN 1 THEN niv_cod1
WHEN 2 THEN niv_cod1 || '|' || niv_cod2
WHEN 3 THEN niv_cod1 || '|' || niv_cod2 || '|' || niv_cod3
WHEN 4 THEN niv_cod1 || '|' || niv_cod2 || '|' || niv_cod3 || '|' || niv_cod4
END AS service_code_original,
CASE octime_ets_id.valeur
WHEN 0 THEN octime_ets_manuel.valeur
WHEN 1 THEN niv_cod1 -- cas AHO
WHEN 2 THEN niv_cod2
WHEN 3 THEN niv_cod3
WHEN 4 THEN CASE WHEN octime_max_niveau.valeur = '3' THEN left(prod_octime_cptres1.pers_mat, -5) ELSE niv_cod4 END -- cas Fondation Hopale avec OCTIME_MAX_NIVEAU positionné par défaut sur 3.
WHEN 9 THEN left(prod_octime_cptres1.pers_mat, -5) -- cas Fondation Hopale
END AS entets_code,
cal_val26 AS abs_cod,
hor_cod, -- code horaire.
0 AS temps_du,
0 AS temps_du_initial,
0 AS temps_valide,
0 AS temps_absence,
cal_val387/60.0 AS temps_hs,
0 AS temps_hc
FROM prod_octime_cptres1
JOIN w_sal_pla ON w_sal_pla.salarie_corr = prod_octime_cptres1.salarie_corr
JOIN (SELECT valeur FROM rh.t_divers WHERE code = 'OCTIME_SERVICE_ID') AS octime_service_id ON 1=1
JOIN (SELECT valeur FROM rh.t_divers WHERE code = 'OCTIME_ETS_ID') AS octime_ets_id ON 1=1
JOIN (SELECT valeur FROM rh.t_divers WHERE code = 'OCTIME_ETS_MANUEL') AS octime_ets_manuel ON 1=1
JOIN (SELECT valeur FROM rh.t_divers WHERE code = 'OCTIME_MAX_NIVEAU') AS octime_max_niveau ON 1=1
WHERE cal_val387 != 0
;
INSERT INTO w_cptres1
SELECT
nextval('w_cptres1_seq') as cptres1_id,
prod_octime_cptres1.salarie_corr,
w_sal_pla.salarie_id,
null::bigint AS contrat_id,
null::bigint AS contrat_mois_id,
date(cal_dat) AS date,
pos_cod,
niv_cod1,
niv_cod2,
niv_cod3,
niv_cod4,
CASE octime_max_niveau.valeur
WHEN 3 THEN niv_cod1 || '|' || niv_cod2 || '|' || niv_cod3
WHEN 4 THEN niv_cod1 || '|' || niv_cod2 || '|' || niv_cod3 || '|' || niv_cod4
END AS niveau_code_original,
CASE octime_service_id.valeur
WHEN 1 THEN niv_cod1
WHEN 2 THEN niv_cod1 || '|' || niv_cod2
WHEN 3 THEN niv_cod1 || '|' || niv_cod2 || '|' || niv_cod3
WHEN 4 THEN niv_cod1 || '|' || niv_cod2 || '|' || niv_cod3 || '|' || niv_cod4
END AS service_code_original,
CASE octime_ets_id.valeur
WHEN 0 THEN octime_ets_manuel.valeur
WHEN 1 THEN niv_cod1 -- cas AHO
WHEN 2 THEN niv_cod2
WHEN 3 THEN niv_cod3
WHEN 4 THEN CASE WHEN octime_max_niveau.valeur = '3' THEN left(prod_octime_cptres1.pers_mat, -5) ELSE niv_cod4 END -- cas Fondation Hopale avec OCTIME_MAX_NIVEAU positionné par défaut sur 3.
WHEN 9 THEN left(prod_octime_cptres1.pers_mat, -5) -- cas Fondation Hopale
END AS entets_code,
cal_val26 AS abs_cod,
hor_cod, -- code horaire.
0 AS temps_du,
0 AS temps_du_initial,
0 AS temps_valide,
0 AS temps_absence,
0 AS temps_hs,
cal_val388/60.0 AS temps_hc
FROM prod_octime_cptres1
JOIN w_sal_pla ON w_sal_pla.salarie_corr = prod_octime_cptres1.salarie_corr
JOIN (SELECT valeur FROM rh.t_divers WHERE code = 'OCTIME_SERVICE_ID') AS octime_service_id ON 1=1
JOIN (SELECT valeur FROM rh.t_divers WHERE code = 'OCTIME_ETS_ID') AS octime_ets_id ON 1=1
JOIN (SELECT valeur FROM rh.t_divers WHERE code = 'OCTIME_ETS_MANUEL') AS octime_ets_manuel ON 1=1
JOIN (SELECT valeur FROM rh.t_divers WHERE code = 'OCTIME_MAX_NIVEAU') AS octime_max_niveau ON 1=1
WHERE cal_val388 != 0
;
-- Permet de s'assurer que le Niveau Planning non renseigné sera bien celui avec l'OID 0.
UPDATE w_cptres1 SET
niveau_code_original = ''
WHERE niveau_code_original = '||'
;
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)
with w_cptres1_tmp as (
select
service_code_original,
niv_cod1,
niv_cod2,
niv_cod3,
niv_cod4,
octime_service_id.valeur
from w_cptres1
JOIN (SELECT valeur FROM rh.t_divers WHERE code = 'OCTIME_SERVICE_ID') AS octime_service_id ON 1=1
group by 1,2,3,4,5,6)
SELECT
w_cptres1.service_code_original,
w_cptres1.service_code_original,
coalesce(niv1.niv_lib1, w_cptres1.niv_cod1)||case when valeur >= 2 THEN ' - '||coalesce(niv2.niv_lib2, w_cptres1.niv_cod2) ELSE '' END||CASE WHEN valeur >= 3 THEN ' - '||coalesce(niv3.niv_lib3, w_cptres1.niv_cod3) ELSE '' END||CASE WHEN valeur >= 4 THEN ' - '||coalesce(niv4.niv_lib4, w_cptres1.niv_cod4) ELSE '' END,
substr(coalesce(niv1.niv_lib1, w_cptres1.niv_cod1)||case when valeur >= 2 THEN ' - '||coalesce(niv2.niv_lib2, w_cptres1.niv_cod2) ELSE '' END||CASE WHEN valeur >= 3 THEN ' - '||coalesce(niv3.niv_lib3, w_cptres1.niv_cod3) ELSE '' END||CASE WHEN valeur >= 4 THEN ' - '||coalesce(niv4.niv_lib4, w_cptres1.niv_cod4) ELSE '' END, 1, 50),
0 as service_id
FROM w_cptres1_tmp as w_cptres1
LEFT JOIN prod_octime_niveau1 as niv1 ON niv1.niv_cod1 = w_cptres1.niv_cod1
LEFT JOIN prod_octime_niveau2 as niv2 ON 1=1
AND niv2.niv_cod1 = w_cptres1.niv_cod1
AND niv2.niv_cod2 = w_cptres1.niv_cod2
LEFT JOIN prod_octime_niveau3 as niv3 ON 1=1
AND niv3.niv_cod1 = w_cptres1.niv_cod1
AND niv3.niv_cod2 = w_cptres1.niv_cod2
AND niv3.niv_cod3 = w_cptres1.niv_cod3
LEFT JOIN prod_octime_niveau4 as niv4 ON 1=1
AND niv4.niv_cod1 = w_cptres1.niv_cod1
AND niv4.niv_cod2 = w_cptres1.niv_cod2
AND niv4.niv_cod3 = w_cptres1.niv_cod3
AND niv4.niv_cod4 = w_cptres1.niv_cod4
WHERE w_cptres1.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 Niveaux du Planning.
DROP TABLE IF EXISTS w_nivpla
;
CREATE TEMP TABLE w_nivpla AS
with w_cptres1_tmp as (
select
niveau_code_original,
niv_cod1,
niv_cod2,
niv_cod3,
niv_cod4,
octime_max_niveau.valeur as octime_max_niveau
from w_cptres1
JOIN (SELECT valeur FROM rh.t_divers WHERE code = 'OCTIME_MAX_NIVEAU') AS octime_max_niveau ON 1=1
group by 1,2,3,4,5,6)
SELECT
w_cptres1.niveau_code_original,
coalesce(niv1.niv_lib1, w_cptres1.niv_cod1)||' -|- '||coalesce(niv2.niv_lib2, w_cptres1.niv_cod2)||' -|- '||coalesce(niv3.niv_lib3, w_cptres1.niv_cod3)||case when octime_max_niveau = 4 then ' -|- '||coalesce(niv4.niv_lib4, w_cptres1.niv_cod4) else '' end as niv_txt,
substr(coalesce(niv1.niv_lib1, w_cptres1.niv_cod1)||' -|- '||coalesce(niv2.niv_lib2, w_cptres1.niv_cod2)||' -|- '||coalesce(niv3.niv_lib3, w_cptres1.niv_cod3)||case when octime_max_niveau = 4 then ' -|- '||coalesce(niv4.niv_lib4, w_cptres1.niv_cod4) else '' end, 1, 50) as niv_txt_crt
FROM w_cptres1_tmp as w_cptres1
LEFT JOIN prod_octime_niveau1 as niv1 ON niv1.niv_cod1 = w_cptres1.niv_cod1
LEFT JOIN prod_octime_niveau2 as niv2 ON 1=1
AND niv2.niv_cod1 = w_cptres1.niv_cod1
AND niv2.niv_cod2 = w_cptres1.niv_cod2
LEFT JOIN prod_octime_niveau3 as niv3 ON 1=1
AND niv3.niv_cod1 = w_cptres1.niv_cod1
AND niv3.niv_cod2 = w_cptres1.niv_cod2
AND niv3.niv_cod3 = w_cptres1.niv_cod3
LEFT JOIN prod_octime_niveau4 as niv4 ON 1=1
AND niv4.niv_cod1 = w_cptres1.niv_cod1
AND niv4.niv_cod2 = w_cptres1.niv_cod2
AND niv4.niv_cod3 = w_cptres1.niv_cod3
AND niv4.niv_cod4 = w_cptres1.niv_cod4
WHERE 1=1
AND niveau_code_original != ''
GROUP BY 1,2,3
;
-- Màj des libellés uniquement.
UPDATE rh.t_planning_niveau SET
texte = niv_txt,
texte_court = niv_txt_crt
FROM w_nivpla
WHERE 1=1
AND t_planning_niveau.code_original = w_nivpla.niveau_code_original
AND (1!=1
OR t_planning_niveau.texte IS DISTINCT FROM w_nivpla.niv_txt
OR t_planning_niveau.texte_court IS DISTINCT FROM w_nivpla.niv_txt_crt)
;
-- Insertion des nouveaux niveaux de planning.
INSERT INTO rh.t_planning_niveau(code_original, code, texte, texte_court)
SELECT
w_nivpla.niveau_code_original,
w_nivpla.niveau_code_original,
w_nivpla.niv_txt,
w_nivpla.niv_txt_crt
FROM w_nivpla
JOIN w_cptres1 ON w_cptres1.niveau_code_original = w_nivpla.niveau_code_original
WHERE w_nivpla.niveau_code_original NOT IN (SELECT code_original FROM rh.t_planning_niveau WHERE code_original IS NOT NULL GROUP BY 1)
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
pos_cod,
pos_cod,
pos_lib,
pos_lib
FROM prod_octime_poste AS poste
WHERE 1=1
AND pos_cod IN (SELECT pos_cod FROM w_cptres1)
AND pos_cod 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
abs_cod,
abs_cod,
abs_lib,
abs_lib
FROM prod_octime_absence AS absence
WHERE 1=1
AND abs_cod IN (SELECT abs_cod FROM w_cptres1)
AND abs_cod 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
hor_cod,
hor_abr,
substr(hor_dmis, 1, 2)||'h'||substr(hor_dmis, 3, 2)||'-'||substr(hor_fmis, 1, 2)||'h'||substr(hor_fmis, 3, 2)||' ('||substr(hor_tmis, 1, 2)||':'||substr(hor_tmis, 3, 2)||')',
substr(substr(hor_dmis, 1, 2)||'h'||substr(hor_dmis, 3, 2)||'-'||substr(hor_fmis, 1, 2)||'h'||substr(hor_fmis, 3, 2)||' ('||substr(hor_tmis, 1, 2)||':'||substr(hor_tmis, 3, 2)||')', 1, 50)
FROM prod_octime_cjourn AS cjourn
WHERE 1=1
AND hor_cod IN (SELECT hor_cod FROM w_cptres1)
AND hor_cod NOT IN (SELECT code_original FROM rh.t_planning_code_horaire WHERE code_original IS NOT NULL)
;
-- Forçage des libellés et codes horaires lorsqu'ils sautent
UPDATE rh.t_planning_code_horaire
SET code = hor_abr,
texte = substr(hor_dmis, 1, 2)||'h'||substr(hor_dmis, 3, 2)||'-'||substr(hor_fmis, 1, 2)||'h'||substr(hor_fmis, 3, 2)||' ('||substr(hor_tmis, 1, 2)||':'||substr(hor_tmis, 3, 2)||')',
texte_court = substr(substr(hor_dmis, 1, 2)||'h'||substr(hor_dmis, 3, 2)||'-'||substr(hor_fmis, 1, 2)||'h'||substr(hor_fmis, 3, 2)||' ('||substr(hor_tmis, 1, 2)||':'||substr(hor_tmis, 3, 2)||')', 1, 50)
FROM prod_octime_cjourn AS cjourn
WHERE code_original = hor_cod AND
(code <> hor_abr OR
texte <> substr(hor_dmis, 1, 2)||'h'||substr(hor_dmis, 3, 2)||'-'||substr(hor_fmis, 1, 2)||'h'||substr(hor_fmis, 3, 2)||' ('||substr(hor_tmis, 1, 2)||':'||substr(hor_tmis, 3, 2)||')' OR
texte_court <> substr(substr(hor_dmis, 1, 2)||'h'||substr(hor_dmis, 3, 2)||'-'||substr(hor_fmis, 1, 2)||'h'||substr(hor_fmis, 3, 2)||' ('||substr(hor_tmis, 1, 2)||':'||substr(hor_tmis, 3, 2)||')', 1, 50))
;
-- 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
;
-- Ajout de l'établissement en cours si la valeur de OCTIME_REPRISE_HISTO est à 1 (reprise de l'histo paramétré) car le max renvoi l'établissement historique
WITH w_ets_encours_reprise_histo AS
(SELECT ent.oid as entreprise_id,
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
JOIN rh.t_divers ON t_divers.code IN ('OCTIME_REPRISE_HISTO')
LEFT JOIN w_entets ON w_entets.entreprise_id = ent.oid AND w_entets.etablissement_id = ets.oid
WHERE 1=1
AND ent.oid != 0
AND ets.oid != 0
AND ent.planning_code||ets.planning_code != ''
AND t_divers.valeur = 1
AND w_entets.etablissement_id IS NULL)
INSERT INTO w_entets SELECT * FROM w_ets_encours_reprise_histo;
-- 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,
temps_du_initial,
temps_valide,
temps_absence,
temps_du_ajuste,
temps_valide_ajuste,
temps_absence_ajuste)
SELECT
w_cptres1.salarie_id,
w_cptres1.contrat_id,
w_cptres1.contrat_mois_id,
w_cptres1.date,
to_char(w_cptres1.date, 'IYYYIW'::text)::numeric AS semaine,
to_char(w_cptres1.date, 'YYYYMM'::text)::numeric AS mois,
coalesce(w_entets.etablissement_id, 0) as etablissement_id,
coalesce(t_planning_service.oid, 0) AS service_id,
coalesce(t_planning_qualification.oid, 0) AS qualification_id,
coalesce(t_planning_type_absence.oid, 0) AS type_absence_id,
coalesce(t_planning_niveau.oid, 0) as niveau_id,
coalesce(t_planning_code_horaire.oid, 0) as code_horaire_id,
temps_du,
temps_du_initial,
temps_valide,
temps_absence,
temps_du,
temps_valide,
temps_absence
FROM w_cptres1
JOIN rh.p_salaries ON p_salaries.oid = w_cptres1.salarie_id
JOIN w_entets ON true
AND w_entets.entreprise_id = p_salaries.entreprise_id
AND w_entets.entets_code = w_cptres1.entets_code -- Limiter les données au seul établissement paramétré.
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.pos_cod
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.hor_cod
GROUP BY 1,2,3,4,5,6,7,8,9,10,11,12,13,14,15,16,17,18,19
;
VACUUM ANALYSE rh.p_planning_mouvement
;
-- Ajustement des temps
-- Temps validé sans temps du, alimenter temps du
UPDATE rh.p_planning_mouvement
SET temps_du_ajuste = p_planning_mouvement.temps_valide
FROM
(
SELECT salarie_id, date
FROM rh.p_planning_mouvement
JOIN RH.t_divers ON t_divers.code = 'OCTIME_TPS_VALIDE_A' AND t_divers.valeur = '1'
GROUP BY 1,2
HAVING SUM(temps_du) = 0 AND SUM(temps_valide) > 0
) subview
WHERE p_planning_mouvement.salarie_id = subview.salarie_id AND
p_planning_mouvement.date = subview.date
;
-- Temps du - temps absence différent de temps validé -> temps valide = Temps du - temps absence
UPDATE rh.p_planning_mouvement
SET temps_valide_ajuste = p_planning_mouvement.temps_valide + ecart_temps_valide
FROM
(
SELECT salarie_id, date, SUM(temps_du_ajuste) AS temps_du_ajuste, SUM(temps_valide) AS temps_valide, SUM(temps_absence) AS temps_absence,
MIN(CASE WHEN temps_du_ajuste > 0 THEN p_planning_mouvement.CTID ELSE NULL END) AS upd_ctid, SUM(temps_du_ajuste) - SUM(temps_absence) - SUM(temps_valide) AS ecart_temps_valide
FROM rh.p_planning_mouvement
JOIN RH.t_divers ON t_divers.code = 'OCTIME_TPS_VALIDE_A' AND t_divers.valeur = '1'
GROUP BY 1,2
HAVING SUM(temps_du_ajuste) - SUM(temps_absence) <> SUM(temps_valide)
) subview
WHERE p_planning_mouvement.salarie_id = subview.salarie_id AND
p_planning_mouvement.date = subview.date AND
p_planning_mouvement.ctid = subview.upd_ctid
;
]]>
0
FROM rh.t_divers
WHERE code = 'OCTIME_VENTILATION'
;
]]>