|
|
return: text
|
|
|
lang: plpgsql
|
|
|
src: |
|
|
|
DECLARE
|
|
|
result TEXT;
|
|
|
_module_pmsimco TEXT;
|
|
|
BEGIN
|
|
|
|
|
|
RAISE NOTICE '%' , 'Initialisation budget_cles';
|
|
|
-- Contenu table
|
|
|
INSERT INTO rh.t_budget_cle (oid, code, texte, texte_court)
|
|
|
SELECT 0, '**', 'Non renseigné', 'Non renseigné'
|
|
|
WHERE 0 NOT IN (SELECT oid FROM rh.t_budget_cle);
|
|
|
|
|
|
|
|
|
-- Oids des sections de classe
|
|
|
DROP TABLE IF EXISTS w_classe_section_to_id;
|
|
|
CREATE TEMP TABLE w_classe_section_to_id AS
|
|
|
SELECT '[CLASSE:'||t_classes.code||':'||t_classes_sections.code||']' AS classe_section_code, to_id AS classe_section_to_id
|
|
|
FROM rh.t_classes
|
|
|
JOIN rh.t_classes_sections ON classe_id = t_classes.oid
|
|
|
JOIN rh.t_classes_sections_elements ON section_id = t_classes_sections.oid
|
|
|
WHERE t_classes.code <> ''
|
|
|
GROUP BY 1,2
|
|
|
;
|
|
|
|
|
|
-- Traduction des règles en oid
|
|
|
RAISE NOTICE '%' , 'Application des regles. Traduction en oid';
|
|
|
DROP TABLE IF EXISTS w_budget_cle_rule;
|
|
|
CREATE TEMP TABLE w_budget_cle_rule AS
|
|
|
SELECT
|
|
|
t_budget_cle_rule.oid,
|
|
|
budget_cle_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
|
|
|
FROM rh.t_budget_cle_rule
|
|
|
JOIN rh.t_budget_cle ON budget_cle_id = t_budget_cle.oid
|
|
|
ORDER BY priorite, budget_cle_id;
|
|
|
|
|
|
DELETE FROM w_budget_cle_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) = 0
|
|
|
;
|
|
|
|
|
|
UPDATE w_budget_cle_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_budget_cle_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_budget_cle_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_budget_cle_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_budget_cle_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_budget_cle_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_budget_cle_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_budget_cle_rule
|
|
|
SET liste_qualification_id = subview.liste_qualification_id
|
|
|
FROM
|
|
|
(
|
|
|
SELECT w_budget_cle_rule.oid,
|
|
|
array_cat(MAX(liste_qualification_id),base.cti_group_array3(classe_section_to_id)) AS liste_qualification_id
|
|
|
FROM w_budget_cle_rule
|
|
|
JOIN w_classe_section_to_id ON classe_section_code = ANY(liste_qualification)
|
|
|
WHERE a_liste_qualification = '1'
|
|
|
GROUP BY 1
|
|
|
) subview
|
|
|
WHERE w_budget_cle_rule.oid = subview.oid
|
|
|
;
|
|
|
|
|
|
|
|
|
UPDATE w_budget_cle_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_budget_cle_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_budget_cle_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';
|
|
|
|
|
|
|
|
|
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 budget_cle_priorite,
|
|
|
COALESCE((MIN(ARRAY[priorite,w_budget_cle_rule.budget_cle_id]))[2],0) AS budget_cle_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_budget_cle_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
|
|
|
GROUP BY 1
|
|
|
ORDER BY 2,1
|
|
|
;
|
|
|
|
|
|
|
|
|
RAISE NOTICE '%' , 'Application des regles. Validation des budget_cles';
|
|
|
|
|
|
UPDATE rh.p_profil_contrat_mois SET
|
|
|
budget_cle_id = w_profil_contrat_mois.budget_cle_id
|
|
|
FROM w_profil_contrat_mois
|
|
|
WHERE p_profil_contrat_mois.oid = w_profil_contrat_mois.oid AND
|
|
|
p_profil_contrat_mois.budget_cle_id IS DISTINCT FROM w_profil_contrat_mois.budget_cle_id
|
|
|
;
|
|
|
|
|
|
UPDATE rh.p_profil_contrat_mois SET
|
|
|
budget_cle_id = 0
|
|
|
WHERE 1=1
|
|
|
AND oid NOT IN (SELECT oid FROM w_profil_contrat_mois group by 1)
|
|
|
AND budget_cle_id IS DISTINCT FROM 0
|
|
|
;
|
|
|
|
|
|
|
|
|
|
|
|
ANALYSE rh.p_profil_contrat_mois
|
|
|
;
|
|
|
|
|
|
INSERT INTO rh.p_oids (code_table, oid)
|
|
|
SELECT 'budget_cle', budget_cle_id
|
|
|
FROM rh.p_profil_contrat_mois
|
|
|
WHERE budget_cle_id NOT IN (SELECT oid FROM rh.p_oids WHERE code_table = 'budget_cle')
|
|
|
GROUP BY 2
|
|
|
;
|
|
|
|
|
|
RETURN 'OK';
|
|
|
END;
|