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.
 
 
 

332 lines
16 KiB

return: text
lang: plpgsql
src: |
DECLARE
result TEXT;
_module_pmsimco TEXT;
BEGIN
RAISE NOTICE '%' , 'Initialisation poles';
-- Contenu table
INSERT INTO base.t_pole (oid, code, texte, texte_court)
SELECT 0, '**', 'Non renseigné', 'Non renseigné'
WHERE 0 NOT IN (SELECT oid FROM base.t_pole);
-- replication dans rh
TRUNCATE rh.t_pole;
INSERT INTO rh.t_pole (oid, code, texte, texte_court, section_id, section_code, section_texte)
SELECT oid, code, texte, texte_court, section_id, section_code, section_texte
FROM base.t_pole
;
-- Traduction des règles en oid
RAISE NOTICE '%' , 'Application des regles. Traduction en oid';
DROP TABLE IF EXISTS w_pole_rule;
CREATE TEMP TABLE w_pole_rule AS
SELECT
t_pole_rule.oid,
pole_id,
priorite,
CASE WHEN liste_finess <> '' THEN '1' ELSE '0' END AS a_liste_finess,
string_to_array(translate(liste_finess,'*,','% '),' ') AS liste_finess,
NULL::bigint[] AS liste_finess_id ,
CASE WHEN liste_etablissement <> '' THEN '1' ELSE '0' END AS a_liste_etablissement,
string_to_array(translate(liste_etablissement,'*,','% '),' ') AS liste_etablissement,
NULL::bigint[] AS liste_etablissement_id ,
CASE WHEN liste_service <> '' THEN '1' ELSE '0' END AS a_liste_service,
string_to_array(translate(liste_service,'*,','% '),' ') AS liste_service,
NULL::bigint[] AS liste_service_id ,
CASE WHEN liste_specialite <> '' THEN '1' ELSE '0' END AS a_liste_specialite,
string_to_array(translate(liste_specialite,'*,','% '),' ') AS liste_specialite,
NULL::bigint[] AS liste_specialite_id ,
CASE WHEN liste_section_analytique <> '' THEN '1' ELSE '0' END AS a_liste_section_analytique,
string_to_array(translate(liste_section_analytique,'*,','% '),' ') AS liste_section_analytique,
NULL::bigint[] AS liste_section_analytique_id ,
CASE WHEN liste_section_analytique_paie <> '' THEN '1' ELSE '0' END AS a_liste_section_analytique_paie,
string_to_array(translate(liste_section_analytique_paie,'*,','% '),' ') AS liste_section_analytique_paie,
NULL::bigint[] AS liste_section_analytique_paie_id ,
CASE WHEN liste_qualification <> '' THEN '1' ELSE '0' END AS a_liste_qualification,
string_to_array(translate(liste_qualification,'*,','% '),' ') AS liste_qualification,
NULL::bigint[] AS liste_qualification_id ,
CASE WHEN liste_grille <> '' THEN '1' ELSE '0' END AS a_liste_grille,
string_to_array(translate(liste_grille,'*,','% '),' ') AS liste_grille,
NULL::bigint[] AS liste_grille_id ,
CASE WHEN liste_code_emploi <> '' THEN '1' ELSE '0' END AS a_liste_code_emploi,
string_to_array(translate(liste_code_emploi,'*,','% '),' ') AS liste_code_emploi,
NULL::bigint[] AS liste_code_emploi_id ,
CASE WHEN liste_categorie_socio_professionnelle <> '' THEN '1' ELSE '0' END AS a_liste_categorie_socio_professionnelle,
string_to_array(translate(liste_categorie_socio_professionnelle,'*,','% '),' ') AS liste_categorie_socio_professionnelle,
NULL::bigint[] AS liste_categorie_socio_professionnelle_id ,
CASE WHEN liste_service_planning <> '' THEN '1' ELSE '0' END AS a_liste_service_planning,
string_to_array(translate(liste_service_planning,'*,','% '),' ') AS liste_service_planning,
NULL::bigint[] AS liste_service_planning_id
FROM rh.t_pole_rule
JOIN rh.t_pole ON pole_id = t_pole.oid
ORDER BY priorite, pole_id;
DELETE FROM w_pole_rule
WHERE
(a_liste_finess::int +
a_liste_etablissement::int +
a_liste_service::int +
a_liste_specialite::int +
a_liste_section_analytique::int +
a_liste_section_analytique_paie::int +
a_liste_qualification::int +
a_liste_grille::int +
a_liste_code_emploi::int +
a_liste_categorie_socio_professionnelle::int +
a_liste_service_planning::int) = 0
;
UPDATE w_pole_rule
SET liste_finess_id = (SELECT base.cti_group_array3(oid) FROM base.t_finess WHERE oid <> 0 AND code LIKE ANY (liste_finess))
WHERE a_liste_finess = '1';
UPDATE w_pole_rule
SET liste_etablissement_id = (SELECT base.cti_group_array3(oid) FROM rh.t_etablissements WHERE oid <> 0 AND code LIKE ANY (liste_etablissement))
WHERE a_liste_etablissement = '1';
UPDATE w_pole_rule
SET liste_service_id = (SELECT base.cti_group_array3(oid) FROM rh.t_services WHERE oid <> 0 AND code LIKE ANY (liste_service))
WHERE a_liste_service = '1';
UPDATE w_pole_rule
SET liste_specialite_id = (SELECT base.cti_group_array3(oid) FROM rh.t_specialites WHERE oid <> 0 AND code LIKE ANY (liste_specialite))
WHERE a_liste_specialite = '1';
UPDATE w_pole_rule
SET liste_section_analytique_id = (SELECT base.cti_group_array3(oid) FROM rh.t_sections_analytiques WHERE oid <> 0 AND code LIKE ANY (liste_section_analytique))
WHERE a_liste_section_analytique = '1';
UPDATE w_pole_rule
SET liste_section_analytique_paie_id = (SELECT base.cti_group_array3(oid) FROM rh.t_sections_analytiques_paie WHERE oid <> 0 AND code LIKE ANY (liste_section_analytique_paie))
WHERE a_liste_section_analytique_paie = '1';
UPDATE w_pole_rule
SET liste_qualification_id = (SELECT base.cti_group_array3(oid) FROM rh.t_qualifications WHERE oid <> 0 AND code LIKE ANY (liste_qualification))
WHERE a_liste_qualification = '1';
UPDATE w_pole_rule
SET liste_grille_id = (SELECT base.cti_group_array3(oid) FROM rh.t_grilles WHERE oid <> 0 AND code LIKE ANY (liste_grille))
WHERE a_liste_grille = '1';
UPDATE w_pole_rule
SET liste_code_emploi_id = (SELECT base.cti_group_array3(oid) FROM rh.t_codes_emploi WHERE oid <> 0 AND code LIKE ANY (liste_code_emploi))
WHERE a_liste_code_emploi = '1';
UPDATE w_pole_rule
SET liste_categorie_socio_professionnelle_id = (SELECT base.cti_group_array3(oid) FROM rh.t_categories_socio_professionnelle WHERE oid <> 0 AND code LIKE ANY (liste_categorie_socio_professionnelle))
WHERE a_liste_categorie_socio_professionnelle = '1';
UPDATE w_pole_rule
SET liste_service_planning_id = (SELECT base.cti_group_array3(oid) FROM rh.t_planning_service WHERE oid <> 0 AND code LIKE ANY (liste_service_planning))
WHERE a_liste_service_planning = '1';
RAISE NOTICE '%' , 'Application des regles.'
;
DROP TABLE IF EXISTS w_profil_contrat_mois
;
CREATE TEMP TABLE w_profil_contrat_mois AS
SELECT
p_profil_contrat_mois.oid,
COALESCE(MIN(priorite),999999999) AS pole_priorite,
COALESCE((MIN(ARRAY[priorite,w_pole_rule.pole_id]))[2],0) AS pole_id
FROM rh.p_profil_contrat_mois
JOIN rh.p_contrats_mois ON p_profil_contrat_mois.contrat_mois_id = p_contrats_mois.oid
JOIN rh.t_etablissements ON t_etablissements.oid = p_contrats_mois.etablissement_id
JOIN rh.p_profils ON p_profil_contrat_mois.profil_id = p_profils.oid
JOIN w_pole_rule ON
(a_liste_finess = '0' OR finess_id = ANY (liste_finess_id)) AND
(a_liste_etablissement = '0' OR p_contrats_mois.etablissement_id = ANY (liste_etablissement_id)) AND
(a_liste_service = '0' OR p_profils.service_id = ANY (liste_service_id)) AND
(a_liste_specialite = '0' OR p_profils.specialite_id = ANY (liste_specialite_id)) AND
(a_liste_qualification = '0' OR p_profils.qualification_id = ANY (liste_qualification_id)) AND
(a_liste_section_analytique = '0' OR p_profils.section_analytique_id = ANY (liste_section_analytique_id)) AND
(a_liste_section_analytique_paie = '0' OR p_profils.section_analytique_paie_id = ANY (liste_section_analytique_paie_id)) AND
(a_liste_grille = '0' OR p_profils.grille_id = ANY (liste_grille_id)) AND
(a_liste_code_emploi = '0' OR p_profils.code_emploi_id = ANY (liste_code_emploi_id)) AND
(a_liste_categorie_socio_professionnelle = '0' OR p_profils.categorie_socio_professionnelle_id = ANY (liste_categorie_socio_professionnelle_id))
-- Pas de service planning.
WHERE
(a_liste_finess::int +
a_liste_etablissement::int +
a_liste_service::int +
a_liste_specialite::int +
a_liste_section_analytique::int +
a_liste_section_analytique_paie::int +
a_liste_qualification::int +
a_liste_grille::int +
a_liste_code_emploi::int +
a_liste_categorie_socio_professionnelle::int) > 0 OR
a_liste_service_planning::int = 0
GROUP BY 1
ORDER BY 2,1
;
DROP TABLE IF EXISTS w_contrats_mois
;
CREATE TEMP TABLE w_contrats_mois AS
SELECT
p_contrats_mois.oid,
COALESCE(MIN(priorite),999999999) AS pole_priorite,
COALESCE((MIN(ARRAY[priorite,w_pole_rule.pole_id]))[2],0) AS pole_id
FROM rh.p_contrats_mois
JOIN rh.t_etablissements ON t_etablissements.oid = p_contrats_mois.etablissement_id
JOIN rh.p_profils ON p_contrats_mois.profil_id = p_profils.oid
JOIN w_pole_rule ON
(a_liste_finess = '0' OR finess_id = ANY (liste_finess_id)) AND
(a_liste_etablissement = '0' OR p_contrats_mois.etablissement_id = ANY (liste_etablissement_id)) AND
(a_liste_service = '0' OR p_profils.service_id = ANY (liste_service_id)) AND
(a_liste_specialite = '0' OR p_profils.specialite_id = ANY (liste_specialite_id)) AND
(a_liste_qualification = '0' OR p_profils.qualification_id = ANY (liste_qualification_id)) AND
(a_liste_section_analytique = '0' OR p_profils.section_analytique_id = ANY (liste_section_analytique_id)) AND
(a_liste_section_analytique_paie = '0' OR p_profils.section_analytique_paie_id = ANY (liste_section_analytique_paie_id)) AND
(a_liste_grille = '0' OR p_profils.grille_id = ANY (liste_grille_id)) AND
(a_liste_code_emploi = '0' OR p_profils.code_emploi_id = ANY (liste_code_emploi_id)) AND
(a_liste_categorie_socio_professionnelle = '0' OR p_profils.categorie_socio_professionnelle_id = ANY (liste_categorie_socio_professionnelle_id))
-- Pas de service planning.
GROUP BY 1
ORDER BY 1
;
DROP TABLE IF EXISTS w_contrats
;
CREATE TEMP TABLE w_contrats AS
SELECT p_contrats.oid,
COALESCE(MIN(priorite),999999999) AS pole_priorite,
COALESCE((MIN(ARRAY[priorite,w_pole_rule.pole_id]))[2],0) AS pole_id
FROM rh.p_contrats
LEFT JOIN rh.t_etablissements ON t_etablissements.oid = etablissement_id
LEFT JOIN rh.p_profils ON p_contrats.profil_id = p_profils.oid
JOIN w_pole_rule ON
(a_liste_finess = '0' OR finess_id = ANY (liste_finess_id)) AND
(a_liste_etablissement = '0' OR p_contrats.etablissement_id = ANY (liste_etablissement_id)) AND
(a_liste_service = '0' OR p_profils.service_id = ANY (liste_service_id)) AND
(a_liste_specialite = '0' OR p_profils.specialite_id = ANY (liste_specialite_id)) AND
(a_liste_qualification = '0' OR p_profils.qualification_id = ANY (liste_qualification_id)) AND
(a_liste_section_analytique = '0' OR p_profils.section_analytique_id = ANY (liste_section_analytique_id)) AND
(a_liste_section_analytique_paie = '0' OR p_profils.section_analytique_paie_id = ANY (liste_section_analytique_paie_id)) AND
(a_liste_grille = '0' OR p_profils.grille_id = ANY (liste_grille_id)) AND
(a_liste_code_emploi = '0' OR p_profils.code_emploi_id = ANY (liste_code_emploi_id)) AND
(a_liste_categorie_socio_professionnelle = '0' OR p_profils.categorie_socio_professionnelle_id = ANY (liste_categorie_socio_professionnelle_id))
-- Pas de service planning.
GROUP BY 1
ORDER BY 1
;
DROP TABLE IF EXISTS w_planning_mouvement
;
CREATE TEMP TABLE w_planning_mouvement AS
SELECT
p_planning_mouvement.ctid as pm_ctid,
COALESCE(MIN(priorite),999999999) AS pole_priorite,
COALESCE((MIN(ARRAY[priorite,w_pole_rule.pole_id]))[2],0) AS pole_id
FROM rh.p_planning_mouvement
JOIN rh.p_contrats ON p_planning_mouvement.contrat_id = p_contrats.oid
JOIN rh.p_contrats_mois ON p_planning_mouvement.contrat_mois_id = p_contrats_mois.oid
JOIN rh.p_profil_contrat_mois ON p_profil_contrat_mois.contrat_mois_id = p_contrats_mois.oid
JOIN rh.p_profils ON p_profil_contrat_mois.profil_id = p_profils.oid
JOIN rh.t_etablissements ON t_etablissements.oid = p_planning_mouvement.etablissement_id
JOIN w_pole_rule ON 1=1
AND (a_liste_finess = '0' OR finess_id = ANY (liste_finess_id))
AND (a_liste_etablissement = '0' OR p_planning_mouvement.etablissement_id = ANY (liste_etablissement_id))
AND (a_liste_service = '0' OR p_profils.service_id = ANY (liste_service_id))
AND (a_liste_specialite = '0' OR p_profils.specialite_id = ANY (liste_specialite_id))
AND (a_liste_qualification = '0' OR p_profils.qualification_id = ANY (liste_qualification_id))
AND (a_liste_section_analytique = '0' OR p_profils.section_analytique_id = ANY (liste_section_analytique_id))
AND (a_liste_section_analytique_paie = '0' OR p_profils.section_analytique_paie_id = ANY (liste_section_analytique_paie_id))
AND (a_liste_grille = '0' OR p_profils.grille_id = ANY (liste_grille_id))
AND (a_liste_code_emploi = '0' OR p_profils.code_emploi_id = ANY (liste_code_emploi_id))
AND (a_liste_categorie_socio_professionnelle = '0' OR p_profils.categorie_socio_professionnelle_id = ANY (liste_categorie_socio_professionnelle_id))
AND (a_liste_service_planning = '0' OR p_planning_mouvement.service_id = ANY (liste_service_planning_id))
GROUP BY 1
ORDER BY 1
;
RAISE NOTICE '%' , 'Application des regles. Validation des poles';
UPDATE rh.p_profil_contrat_mois SET
pole_id = w_profil_contrat_mois.pole_id
FROM w_profil_contrat_mois
WHERE p_profil_contrat_mois.oid = w_profil_contrat_mois.oid AND
p_profil_contrat_mois.pole_id IS DISTINCT FROM w_profil_contrat_mois.pole_id
;
UPDATE rh.p_profil_contrat_mois SET
pole_id = 0
WHERE 1=1
AND oid NOT IN (SELECT oid FROM w_profil_contrat_mois group by 1)
AND pole_id IS DISTINCT FROM 0
;
UPDATE rh.p_contrats_mois SET
pole_id = w_contrats_mois.pole_id
FROM w_contrats_mois
WHERE p_contrats_mois.oid = w_contrats_mois.oid AND
p_contrats_mois.pole_id IS DISTINCT FROM w_contrats_mois.pole_id
;
UPDATE rh.p_contrats_mois SET
pole_id = 0
WHERE 1=1
AND oid NOT IN (SELECT oid FROM w_contrats_mois group by 1)
AND pole_id IS DISTINCT FROM 0
;
UPDATE rh.p_contrats SET
pole_id = w_contrats.pole_id
FROM w_contrats
WHERE p_contrats.oid = w_contrats.oid AND
p_contrats.pole_id IS DISTINCT FROM w_contrats.pole_id
;
UPDATE rh.p_contrats SET
pole_id = 0
WHERE 1=1
AND oid NOT IN (SELECT oid FROM w_contrats group by 1)
AND pole_id IS DISTINCT FROM 0
;
with asso as (
select
p_planning_mouvement.ctid as pm_ctid,
coalesce(w_planning_mouvement.pole_id, 0) as pole_id
from rh.p_planning_mouvement
left join w_planning_mouvement on w_planning_mouvement.pm_ctid = p_planning_mouvement.ctid
)
UPDATE rh.p_planning_mouvement SET
pole_id = asso.pole_id
FROM asso
WHERE 1=1
AND p_planning_mouvement.ctid = asso.pm_ctid
AND p_planning_mouvement.pole_id IS DISTINCT FROM asso.pole_id
;
ANALYSE rh.p_profil_contrat_mois
;
ANALYSE rh.p_contrats_mois
;
ANALYSE rh.p_contrats
;
INSERT INTO rh.p_oids (code_table, oid)
SELECT 'pole', pole_id
FROM rh.p_profil_contrat_mois
WHERE pole_id NOT IN (SELECT oid FROM rh.p_oids WHERE code_table = 'pole')
GROUP BY 2
;
RETURN 'OK';
END;