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.
 
 
 

289 lines
10 KiB

return: text
lang: plpgsql
src: |
DECLARE
result TEXT;
BEGIN
-- Transformations saisies ?
IF NOT EXISTS (SELECT * FROM rh.t_transformation) THEN
RETURN 'OK. Non concerné' ;
END IF;
-- Stockage profil source
UPDATE rh.p_profil_contrat_mois
SET profil_avant_transformation_id = profil_id
WHERE profil_avant_transformation_id IS NULL OR
profil_avant_transformation_id = 0
;
-- Table de travail des profils par contrat peut être concernés
DROP TABLE IF EXISTS w_execute_transform_profils;
CREATE TEMP TABLE w_execute_transform_profils AS
SELECT p_profils.*,
salarie_id,
p_profil_contrat_mois.contrat_mois_id,
date(p_profil_contrat_mois.mois|| '01') AS date_contrat,
'0'::text AS with_transformation,
'0'::text AS est_doublon,
p_profils.oid AS from_profil_id
FROM rh.p_profils
JOIN rh.p_profil_contrat_mois ON p_profil_contrat_mois.profil_avant_transformation_id = p_profils.oid
WHERE
(
service_id IN (SELECT from_service_id FROM rh.t_transformation) OR
qualification_id IN (SELECT from_qualification_id FROM rh.t_transformation) OR
salarie_id IN (SELECT salarie_id FROM rh.t_transformation)
)
;
-- execution des règles
-- Spécifiques salarié
UPDATE w_execute_transform_profils SET
with_transformation = '1',
service_id = CASE WHEN to_service_id = -1 THEN w_execute_transform_profils.service_id ELSE to_service_id END,
qualification_id = CASE WHEN to_qualification_id = -1 THEN w_execute_transform_profils.qualification_id ELSE to_qualification_id END,
oid = nextval('rh.s_profils'::regclass)
FROM rh.t_transformation
WHERE (w_execute_transform_profils.salarie_id = t_transformation.salarie_id AND t_transformation.salarie_id <> -1) AND
(w_execute_transform_profils.service_id = from_service_id OR from_service_id = -1) AND
(w_execute_transform_profils.qualification_id = from_qualification_id OR from_qualification_id = -1) AND
date_contrat BETWEEN t_transformation.date_debut AND t_transformation.date_fin AND
(to_service_id <> -1 OR to_qualification_id <> -1)
;
-- Générales
UPDATE w_execute_transform_profils SET
with_transformation = '1',
service_id = CASE WHEN to_service_id = -1 THEN w_execute_transform_profils.service_id ELSE to_service_id END,
qualification_id = CASE WHEN to_qualification_id = -1 THEN w_execute_transform_profils.qualification_id ELSE to_qualification_id END,
oid = nextval('rh.s_profils'::regclass)
FROM rh.t_transformation
WHERE with_transformation <> '1' AND
(t_transformation.salarie_id = -1) AND
(w_execute_transform_profils.service_id = from_service_id OR from_service_id = -1) AND
(w_execute_transform_profils.qualification_id = from_qualification_id OR from_qualification_id = -1) AND
date_contrat BETWEEN t_transformation.date_debut AND t_transformation.date_fin AND
(to_service_id <> -1 OR to_qualification_id <> -1)
;
-- Traitement des profils cibles en double
DROP TABLE IF EXISTS w_execute_transform_profils_uniques;
CREATE TEMP TABLE w_execute_transform_profils_uniques AS
SELECT
w_execute_transform_profils.from_profil_id,
MIN(oid) AS oid
FROM w_execute_transform_profils
WHERE with_transformation = '1'
GROUP BY 1
HAVING count(distinct
ARRAY[type_contrat_id,
motif_debut_id,
motif_fin_id,
qualification_id,
service_id,
specialite_id,
type_temps_travail_id,
categorie_socio_professionnelle_id,
statut_id,
code_emploi_id,
societe_interim_id,
section_analytique_paie_id,
section_analytique_id,
grille_id,
grille_groupe_id,
type_horaire_id,
groupe_cotisant_id,
unite_fonctionnelle_id,
lettre_budgetaire_id,
commission_paritaire_id,
compte_salarie_id,
categorie_conge_id,
filiere_id,
cadre_emploi_id,
categorie_statutaire_id]) = 1
;
UPDATE w_execute_transform_profils
SET oid = w_execute_transform_profils_uniques.oid,
est_doublon = '1'
FROM w_execute_transform_profils_uniques
WHERE with_transformation = '1' AND
w_execute_transform_profils.from_profil_id = w_execute_transform_profils_uniques.from_profil_id AND
w_execute_transform_profils.oid <> w_execute_transform_profils_uniques.oid
;
-- Ajout des nouveaux profils
INSERT INTO rh.p_profils (
oid,
type_contrat_id,
type_contrat_code_original,
motif_debut_id,
motif_debut_code_original,
motif_fin_id,
motif_fin_code_original,
qualification_id,
qualification_code_original,
service_id,
service_code_original,
specialite_id,
specialite_code_original,
type_temps_travail_id,
type_temps_travail_code_original,
categorie_socio_professionnelle_id,
categorie_socio_professionnelle_code_original,
statut_id,
statut_code_original,
code_emploi_id,
code_emploi_code_original,
societe_interim_id,
societe_interim_code_original,
section_analytique_paie_id,
section_analytique_paie_code_original,
section_analytique_id,
section_analytique_code_original,
grille_id,
grille_code_original,
grille_groupe_id,
grille_groupe_code_original,
type_horaire_id,
type_horaire_code_original,
groupe_cotisant_id,
groupe_cotisant_code_original,
unite_fonctionnelle_id,
unite_fonctionnelle_code_original,
lettre_budgetaire_id,
lettre_budgetaire_code_original,
commission_paritaire_id,
commission_paritaire_code_original,
compte_salarie_id,
compte_salarie_code_original,
categorie_conge_id,
categorie_conge_code_original,
filiere_id,
filiere_code_original,
cadre_emploi_id,
cadre_emploi_code_original,
categorie_statutaire_id,
categorie_statutaire_code_original
)
SELECT
w_execute_transform_profils.oid,
type_contrat_id,
type_contrat_code_original,
motif_debut_id,
motif_debut_code_original,
motif_fin_id,
motif_fin_code_original,
qualification_id,
t_qualifications.code_original AS qualification_code_original,
service_id,
t_services.code_original AS service_code_original,
specialite_id,
specialite_code_original,
type_temps_travail_id,
type_temps_travail_code_original,
categorie_socio_professionnelle_id,
categorie_socio_professionnelle_code_original,
statut_id,
statut_code_original,
code_emploi_id,
code_emploi_code_original,
societe_interim_id,
societe_interim_code_original,
section_analytique_paie_id,
section_analytique_paie_code_original,
section_analytique_id,
section_analytique_code_original,
grille_id,
grille_code_original,
grille_groupe_id,
grille_groupe_code_original,
type_horaire_id,
type_horaire_code_original,
groupe_cotisant_id,
groupe_cotisant_code_original,
unite_fonctionnelle_id,
unite_fonctionnelle_code_original,
lettre_budgetaire_id,
lettre_budgetaire_code_original,
commission_paritaire_id,
commission_paritaire_code_original,
compte_salarie_id,
compte_salarie_code_original,
categorie_conge_id,
categorie_conge_code_original,
filiere_id,
filiere_code_original,
cadre_emploi_id,
cadre_emploi_code_original,
categorie_statutaire_id,
categorie_statutaire_code_original
FROM w_execute_transform_profils
JOIN rh.t_services ON service_id = t_services.oid
JOIN rh.t_qualifications On qualification_id = t_qualifications.oid
WHERE with_transformation = '1' AND
est_doublon <> '1'
;
-- Mise à jour des profils par mois
UPDATE rh.p_profil_contrat_mois
SET profil_id = w_execute_transform_profils.oid
FROM w_execute_transform_profils
WHERE p_profil_contrat_mois.contrat_mois_id = w_execute_transform_profils.contrat_mois_id AND
p_profil_contrat_mois.profil_avant_transformation_id = w_execute_transform_profils.from_profil_id AND
with_transformation = '1'
;
-- Mise à jour des contrats avec dernière valeur des profils
UPDATE rh.p_contrats
SET profil_id = new_execute_transform_profil_id
FROM
(
SELECT
p_contrats_mois.contrat_id,
(MAX(ARRAY[p_profil_contrat_mois.mois * 100 + p_profil_contrat_mois.ratio,p_profil_contrat_mois.profil_id]))[2] AS new_execute_transform_profil_id,
MAX(p_contrats.profil_id) AS old_profil_id
FROM rh.p_profil_contrat_mois
JOIN rh.p_contrats_mois ON contrat_mois_id = p_contrats_mois.oid
JOIN rh.p_contrats ON p_contrats_mois.contrat_id = p_contrats.oid
GROUP BY 1
HAVING (MAX(ARRAY[p_profil_contrat_mois.mois * 100 + p_profil_contrat_mois.ratio,p_profil_contrat_mois.profil_id]))[2] <> MAX(p_contrats.profil_id)
) subview
WHERE subview.contrat_id = p_contrats.oid
;
-- Mise à jour des salariés avec dernière valeur des profils
UPDATE rh.p_salaries
SET profil_id = new_execute_transform_profil_id
FROM
(
SELECT
p_profil_contrat_mois.salarie_id,
(MAX(ARRAY[p_profil_contrat_mois.mois * 100 + p_profil_contrat_mois.ratio,p_profil_contrat_mois.profil_id]))[2] AS new_execute_transform_profil_id,
MAX(p_salaries.profil_id) AS old_profil_id
FROM rh.p_profil_contrat_mois
JOIN rh.p_salaries ON p_profil_contrat_mois.salarie_id = p_salaries.oid
GROUP BY 1
HAVING (MAX(ARRAY[p_profil_contrat_mois.mois * 100 + p_profil_contrat_mois.ratio,p_profil_contrat_mois.profil_id]))[2] <> MAX(p_salaries.profil_id)
) subview
WHERE subview.salarie_id = p_salaries.oid
;
-- Ajout des éventuels nouveaux oids
INSERT INTO rh.p_oids (code_table, oid)
SELECT 'services', service_id
FROM rh.p_profils
WHERE service_id NOT IN (SELECT oid FROM rh.p_oids WHERE code_table = 'services')
GROUP BY 1,2
;
INSERT INTO rh.p_oids (code_table, oid)
SELECT 'qualifications', qualification_id
FROM rh.p_profils
WHERE qualification_id NOT IN (SELECT oid FROM rh.p_oids WHERE code_table = 'qualifications')
GROUP BY 1,2
;
-- Réorganisation des nouveaux profils créés
PERFORM rh.cti_reorganize_profils();
PERFORM rh.cti_update_schema_classes('QUA');
PERFORM rh.cti_update_schema_classes('SER');
RETURN 'OK';
END;