You can not select more than 25 topics Topics must start with a letter or number, can include dashes ('-') and can be up to 35 characters long.
 
 
 

512 lines
22 KiB

<?xml version="1.0" encoding="ISO-8859-1"?>
<ROOT>
<NODE name="RAZ">
<NODE label="Nettoyage des tables">
<sqlcmd><![CDATA[
TRUNCATE rh.p_planning_mouvement
;
]]></sqlcmd>
</NODE>
</NODE>
<NODE name="DISABLE_INDEX" label="DESACTIVATION INDEX">
<NODE label="Mouvements du planning">
<sqlcmd><![CDATA[
SELECT base.cti_stash_table_constraints('rh.p_planning_mouvement')
;
SELECT base.cti_stash_table_indexes('rh.p_planning_mouvement')
;
]]></sqlcmd>
</NODE>
</NODE>
<NODE name="ENABLE_INDEX" label="REACTIVATION INDEX">
<NODE label="Mouvements du planning">
<sqlcmd><![CDATA[
SELECT base.cti_stash_pop_table_constraints('rh.p_planning_mouvement')
;
SELECT base.cti_stash_pop_table_indexes('rh.p_planning_mouvement')
;
]]></sqlcmd>
</NODE>
</NODE>
<NODE name="INIT">
<NODE label="Paramètres">
<sqlcmd><![CDATA[
INSERT INTO rh.t_planning_type_absence(oid, code_original, code, texte, texte_court)
SELECT 0, '', chr(1)||'*', 'Non renseigné', 'Non renseigné'
WHERE 0 NOT IN (SELECT oid FROM rh.t_planning_type_absence)
;
INSERT INTO rh.t_planning_qualification(oid, code_original, code, texte, texte_court)
SELECT 0, '', chr(1)||'*', 'Non renseignée', 'Non renseignée'
WHERE 0 NOT IN (SELECT oid FROM rh.t_planning_qualification)
;
INSERT INTO rh.t_planning_service(oid, code_original, code, texte, texte_court)
SELECT 0, '', chr(1)||'*', 'Non renseigné', 'Non renseigné'
WHERE 0 NOT IN (SELECT oid FROM rh.t_planning_service)
;
INSERT INTO rh.t_planning_niveau(oid, code_original, code, texte, texte_court)
SELECT 0, '', chr(1)||'*', 'Non renseigné', 'Non renseigné'
WHERE 0 NOT IN (SELECT oid FROM rh.t_planning_niveau)
;
INSERT INTO rh.t_planning_code_horaire(oid, code_original, code, texte, texte_court)
SELECT 0, '', chr(1)||'*', 'Non renseigné', 'Non renseigné'
WHERE 0 NOT IN (SELECT oid FROM rh.t_planning_code_horaire)
;
]]></sqlcmd>
</NODE>
</NODE>
<NODE name="POST">
<NODE label="Compléments Planning">
<sqlcmd><![CDATA[
-- Identification des évènements d'absences (plusieurs jours consécutifs de même motif d'absence) et comptage du nombre de jours total.
with toto as (
select
salarie_id,
date,
replace(replace(array_to_string(array_agg(type_absence_id) over w, '|'), '|0', ''), '0|', '') as type_absence_id
from rh.p_planning_mouvement
window w as (partition by salarie_id, date)
order by 2 desc
)
, toto2 as (
select
salarie_id,
date,
array_agg(distinct type_absence_id) as type_absence_id
from toto
group by 1,2
order by 2 desc
)
, toto3 as (
select
salarie_id,
date,
type_absence_id,
row_number() over (order by salarie_id, date, type_absence_id) as rang
from toto2
)
, toto4 as (
select
salarie_id,
date,
unnest(type_absence_id) as type_absence_id,
rang
from toto3
order by 2 desc
)
, clustering as (
select
t1.salarie_id,
t1.date,
t1.type_absence_id,
t1.rang,
case
when t1.type_absence_id = 0 then null
when t2.type_absence_id is null then true
else null
end as new_cluster
from toto4 as t1
left join toto4 as t2 on true
and t1.salarie_id = t2.salarie_id
and t1.type_absence_id = t2.type_absence_id
-- and t1.rang = t2.rang + 1 -- permettait d'identifier des jours non consécutifs mais de même motifs (ex: week-end maladie).
and t1.date = t2.date + 1
order by 2 desc
)
, assigned_clustering as (
select
salarie_id,
rang,
date,
type_absence_id,
new_cluster,
nullif(count(new_cluster) over (order by salarie_id, type_absence_id, date rows unbounded preceding), 0) as cluster_id
from clustering
order by 3 desc
)
, abs as (
select
salarie_id,
rang,
date,
type_absence_id,
cluster_id as abs_id,
count(cluster_id) over (partition by cluster_id) as nb_jours
from assigned_clustering
where type_absence_id != 0
)
update rh.p_planning_mouvement set
absence_id = abs.abs_id,
absence_nb_jours = abs.nb_jours
from abs
where 1=1
and p_planning_mouvement.salarie_id = abs.salarie_id
and p_planning_mouvement.date = abs.date
and p_planning_mouvement.type_absence_id = abs.type_absence_id
;
]]></sqlcmd>
</NODE>
<NODE label="Post traitements planning">
<sqlcmd><![CDATA[
-- essayer de faire un rapprochement des qualifications et services selon le paramétrage
UPDATE rh.t_planning_qualification SET
qualification_id = t_qualifications.oid
FROM rh.t_qualifications
JOIN rh.t_divers ON t_divers.code = 'QUALIF_ASSOC'
WHERE 1=1
AND valeur != 0
AND t_planning_qualification.qualification_id = 0
AND ((t_qualifications.code = t_planning_qualification.code AND valeur IN (1,3)) OR valeur = 2 )
AND ((t_qualifications.texte = t_planning_qualification.texte AND valeur IN (2,3)) OR valeur = 1 )
;
UPDATE rh.t_planning_service SET
service_id = t_services.oid
FROM rh.t_services
JOIN rh.t_divers ON t_divers.code = 'SERVICE_ASSOC'
WHERE 1=1
AND valeur != 0
AND t_planning_service.service_id = 0
AND ((t_services.code = t_planning_service.code AND valeur IN (1,3)) OR valeur = 2 )
AND ((t_services.texte = right(t_planning_service.texte, length(t_services.texte)) AND valeur IN (2,3)) OR valeur = 1 )
;
-- Report des Qualification Paie sur Qualification Planning.
UPDATE rh.t_planning_qualification SET
qualification_code = t_qualifications.code,
qualification_texte = t_qualifications.texte_court,
qualification_section_id = t_qualifications.section_id,
qualification_section_code = t_qualifications.section_code,
qualification_section_texte = t_qualifications.section_texte
FROM rh.t_qualifications
WHERE 1=1
AND t_planning_qualification.qualification_id = t_qualifications.oid
AND (1!=1
OR qualification_code IS DISTINCT FROM t_qualifications.code
OR qualification_texte IS DISTINCT FROM t_qualifications.texte_court
OR qualification_section_id IS DISTINCT FROM t_qualifications.section_id
OR qualification_section_code IS DISTINCT FROM t_qualifications.section_code
OR qualification_section_texte IS DISTINCT FROM t_qualifications.section_texte)
;
-- Report des Services Paie sur Services Planning.
UPDATE rh.t_planning_service SET
service_code = t_services.code,
service_texte = t_services.texte_court,
service_section_id = t_services.section_id,
service_section_code = t_services.section_code,
service_section_texte = t_services.section_texte
FROM rh.t_services
WHERE 1=1
AND t_planning_service.service_id = t_services.oid
AND (1!=1
OR service_code IS DISTINCT FROM t_services.code
OR service_texte IS DISTINCT FROM t_services.texte_court
OR service_section_id IS DISTINCT FROM t_services.section_id
OR service_section_code IS DISTINCT FROM t_services.section_code
OR service_section_texte IS DISTINCT FROM t_services.section_texte)
;
-- Création des 3 classes de niveaux.
DROP TABLE IF EXISTS w_classes
;
CREATE TEMP TABLE w_classes AS
with classe_table as (
select 'PLANIV1' as code, '[DICT.RH.NIVEAU1#1]' as texte, 1 as sequence
UNION ALL
select 'PLANIV2' as code, '[DICT.RH.NIVEAU2#1]' as texte, 2 as sequence
UNION ALL
select 'PLANIV3' as code, '[DICT.RH.NIVEAU3#1]' as texte, 3 as sequence)
SELECT code, texte, table_id, 0 as is_cti, sequence
FROM classe_table, (select oid as table_id from rh.t_listes_tables where code = 'PNI' LIMIT 1) as subq
;
insert into rh.t_classes (code, texte, table_id, is_cti, sequence)
select code, texte, table_id, is_cti, sequence
FROM w_classes
where code NOT in (select code from rh.t_classes where code is not null)
;
update rh.t_classes set
texte = w_classes.texte
FROM w_classes
WHERE true
and w_classes.code = t_classes.code
and w_classes.texte is distinct from t_classes.texte
;
-- Nettoyage du contenu
delete from rh.t_classes_sections_elements
where section_id in (
select s.oid from rh.t_classes as c
join rh.t_classes_sections as s on s.classe_id = c.oid
where c.code IN ('PLANIV1', 'PLANIV2', 'PLANIV3'))
;
-- Mise à jour des sections Niveau 1.
DROP TABLE IF EXISTS w_clasec_1
;
CREATE TEMP TABLE w_clasec_1 AS
SELECT
-- On ne travaille pas sur le code_original pour 2 raisons :
-- * pose pb lors de la conso (stratégie où l'oid écrase le code_original)
-- * permet de prendre en compte les éventuelles modifications de l'utilisateur.
split_part(code, '|', 1) as code,
trim(split_part(texte, '-|-', 1)) as texte,
(select oid from rh.t_classes where code = 'PLANIV1') as classe_id
FROM rh.t_planning_niveau
WHERE oid > 0
GROUP BY 1,2,3
;
INSERT INTO rh.t_classes_sections(code, texte, classe_id)
SELECT code, texte, classe_id
from w_clasec_1
where 1=1
and classe_id = (select oid from rh.t_classes where code = 'PLANIV1')
and code not in (select code from rh.t_classes_sections where t_classes_sections.classe_id = w_clasec_1.classe_id and code is not null)
group by 1,2,3
;
update rh.t_classes_sections set
texte = w_clasec_1.texte
FROM w_clasec_1
WHERE true
and w_clasec_1.classe_id = t_classes_sections.classe_id
and w_clasec_1.code = t_classes_sections.code
and w_clasec_1.texte is distinct from t_classes_sections.texte
;
-- Mise à jour du contenu des sections Niveau 1.
INSERT INTO rh.t_classes_sections_elements (section_id, to_id)
SELECT
t_classes_sections.oid AS section_id,
t_planning_niveau.oid AS to_id
FROM rh.t_classes
join rh.t_classes_sections on t_classes_sections.classe_id = t_classes.oid
join rh.t_planning_niveau on split_part(t_planning_niveau.code, '|', 1) = t_classes_sections.code
WHERE t_classes.code = 'PLANIV1'
group by 1,2
;
-- Mise à jour des sections Niveau 2.
DROP TABLE IF EXISTS w_clasec_2
;
CREATE TEMP TABLE w_clasec_2 AS
with nb_niv as (
select
split_part(code, '|', 2) as niv_cod2,
count(DISTINCT trim(split_part(texte, '-|-', 2))) as niv_count
from rh.t_planning_niveau
group by 1
)
SELECT
case when niv_count = 1 then split_part(code, '|', 2) else split_part(code, '|', 1) || '|' || split_part(code, '|', 2) end as code,
split_part(code, '|', 1) || '|' || split_part(code, '|', 2) as code_original,
trim(split_part(texte, '-|-', 2)) as texte,
(select oid from rh.t_classes where code = 'PLANIV2') as classe_id
from rh.t_planning_niveau as niveau2
JOIN nb_niv ON nb_niv.niv_cod2 = split_part(code, '|', 2)
WHERE oid > 0
group by 1,2,3
;
INSERT INTO rh.t_classes_sections(code, texte, classe_id)
SELECT code, texte, classe_id
from w_clasec_2
where 1=1
and classe_id = (select oid from rh.t_classes where code = 'PLANIV2')
and code not in (select code from rh.t_classes_sections where t_classes_sections.classe_id = w_clasec_2.classe_id and code is not null)
group by 1,2,3
;
update rh.t_classes_sections set
texte = w_clasec_2.texte
FROM w_clasec_2
WHERE true
and w_clasec_2.classe_id = t_classes_sections.classe_id
and w_clasec_2.code = t_classes_sections.code
and w_clasec_2.texte is distinct from t_classes_sections.texte
;
-- Mise à jour du contenu des sections Niveau 2.
INSERT INTO rh.t_classes_sections_elements (section_id, to_id)
SELECT
t_classes_sections.oid AS section_id,
t_planning_niveau.oid AS to_id
FROM rh.t_classes
join rh.t_classes_sections on t_classes_sections.classe_id = t_classes.oid
join w_clasec_2 on true
and w_clasec_2.classe_id = t_classes.oid
and w_clasec_2.code = t_classes_sections.code
join rh.t_planning_niveau on split_part(t_planning_niveau.code, '|', 1)||'|'||split_part(t_planning_niveau.code, '|', 2) = w_clasec_2.code_original
WHERE t_classes.code = 'PLANIV2'
group by 1,2
;
-- Mise à jour des sections Niveau 3.
DROP TABLE IF EXISTS w_clasec_3
;
CREATE TEMP TABLE w_clasec_3 AS
with nb_niv as (
select
split_part(code, '|', 3) as niv_cod3,
count(DISTINCT trim(split_part(texte, '-|-', 3))) as niv_count
from rh.t_planning_niveau
group by 1
)
SELECT
case when niv_count = 1 then split_part(code, '|', 3) else split_part(code, '|', 1) || '|' || split_part(code, '|', 2) || '|' || split_part(code, '|', 3) end as code,
split_part(code, '|', 1) || '|' || split_part(code, '|', 2) || '|' || split_part(code, '|', 3) as code_original,
trim(split_part(texte, '-|-', 3)) as texte,
(select oid from rh.t_classes where code = 'PLANIV3') as classe_id
from rh.t_planning_niveau as niveau3
JOIN nb_niv ON nb_niv.niv_cod3 = split_part(code, '|', 3)
WHERE oid > 0
group by 1,2,3
;
INSERT INTO rh.t_classes_sections(code, texte, classe_id)
SELECT code, texte, classe_id
from w_clasec_3
where 1=1
and classe_id = (select oid from rh.t_classes where code = 'PLANIV3')
and code not in (select code from rh.t_classes_sections where t_classes_sections.classe_id = w_clasec_3.classe_id and code is not null)
group by 1,2,3
;
update rh.t_classes_sections set
texte = w_clasec_3.texte
FROM w_clasec_3
WHERE true
and w_clasec_3.classe_id = t_classes_sections.classe_id
and w_clasec_3.code = t_classes_sections.code
and w_clasec_3.texte is distinct from t_classes_sections.texte
;
-- Mise à jour du contenu des sections Niveau 3.
INSERT INTO rh.t_classes_sections_elements (section_id, to_id)
SELECT
t_classes_sections.oid AS section_id,
t_planning_niveau.oid AS to_id
FROM rh.t_classes
join rh.t_classes_sections on t_classes_sections.classe_id = t_classes.oid
join w_clasec_3 on true
and w_clasec_3.classe_id = t_classes.oid
and w_clasec_3.code = t_classes_sections.code
join rh.t_planning_niveau on t_planning_niveau.code = w_clasec_3.code_original
WHERE t_classes.code = 'PLANIV3'
group by 1,2
;
SELECT rh.cti_update_schema_classes('*ALL')
;
-- Recensement des oid utilisés.
INSERT INTO rh.p_oids (code_table, oid)
SELECT 'planning_service', service_id
FROM rh.p_planning_mouvement
WHERE service_id NOT IN (SELECT oid FROM rh.p_oids WHERE code_table = 'planning_service')
GROUP BY 1,2
;
INSERT INTO rh.p_oids (code_table, oid)
SELECT 'planning_qualification', qualification_id
FROM rh.p_planning_mouvement
WHERE qualification_id NOT IN (SELECT oid FROM rh.p_oids WHERE code_table = 'planning_qualification')
GROUP BY 1,2
;
INSERT INTO rh.p_oids (code_table, oid)
SELECT 'planning_niveau', niveau_id
FROM rh.p_planning_mouvement
WHERE niveau_id NOT IN (SELECT oid FROM rh.p_oids WHERE code_table = 'planning_niveau')
GROUP BY 1,2
;
INSERT INTO rh.p_oids (code_table, oid)
SELECT 'planning_type_absence', type_absence_id
FROM rh.p_planning_mouvement
WHERE type_absence_id NOT IN (SELECT oid FROM rh.p_oids WHERE code_table = 'planning_type_absence')
GROUP BY 1,2
;
INSERT INTO rh.p_oids (code_table, oid)
SELECT 'planning_code_horaire', code_horaire_id
FROM rh.p_planning_mouvement
WHERE code_horaire_id NOT IN (SELECT oid FROM rh.p_oids WHERE code_table = 'planning_code_horaire')
GROUP BY 1,2
;
-- Pour remonter le type de contrat intérim.
INSERT INTO rh.p_oids (code_table, oid)
SELECT 'types_contrat', type_contrat_id
FROM rh.p_profils
WHERE type_contrat_id NOT IN (SELECT oid FROM rh.p_oids WHERE code_table = 'types_contrat')
GROUP BY 1,2
;
-- Populations : pas encore de règle de population basée sur le Planning.
-- SELECT rh.cti_reorganize_population()
-- ;
-- Poles
SELECT rh.cti_reorganize_pole()
;
-- Options Divers
INSERT INTO rh.t_divers(
code,
texte,
valeur,
valeur_date,
description)
SELECT
'PLANNING_BASE_ETP'::text,
'Base pour calcul ETP Planning'::text,
'0'::text,
NULL,
'0 : La base des ETP est 151,67h / mois, 1 : La base des ETP est nb jours ouvrés période * 7h13, 2 : La base des ETP est nb jours semaine période * 7'::text
WHERE 'PLANNING_BASE_ETP' NOT IN (SELECT code FROM rh.t_divers)
;
]]></sqlcmd>
</NODE>
</NODE>
<NODE name="VACUUM">
<NODE label="Réorganisation tables">
<sqlcmd><![CDATA[
SELECT base.cti_vacuum('rh.p_oids');
SELECT base.cti_vacuum('rh.p_planning_mouvement');
SELECT base.cti_vacuum('rh.t_planning_niveau');
SELECT base.cti_vacuum('rh.t_planning_qualification');
SELECT base.cti_vacuum('rh.t_planning_service');
SELECT base.cti_vacuum('rh.t_planning_type_absence');
SELECT base.cti_vacuum('rh.p_ventilation');
SELECT base.cti_vacuum('rh.p_ventilation_section');
]]></sqlcmd>
</NODE>
</NODE>
</ROOT>