<?xml version="1.0" encoding="ISO-8859-1"?>
|
|
<ROOT>
|
|
<NODE name="INIT">
|
|
<NODE label="Table Divers">
|
|
<sqlcmd><![CDATA[
|
|
|
|
-- Suppression des codes NOW et NOWCLOTURE.
|
|
-- De cette façon, si l'import du prestataire ne les ajoute pas, le SHARE le fera.
|
|
DELETE FROM rh.t_divers
|
|
WHERE code IN ('NOW', 'NOWCLOTURE')
|
|
;
|
|
|
|
]]></sqlcmd>
|
|
</NODE>
|
|
<NODE label="Paramètres">
|
|
<sqlcmd><![CDATA[
|
|
|
|
-- Màj des codes postaux.
|
|
DELETE
|
|
FROM rh.t_codes_postaux t_codes_postaux_rh
|
|
USING base.t_codes_postaux
|
|
WHERE t_codes_postaux_rh.oid = t_codes_postaux.oid AND
|
|
t_codes_postaux_rh.code <> t_codes_postaux.code
|
|
;
|
|
|
|
INSERT INTO rh.t_codes_postaux(oid, code, texte, texte_court, longitude, latitude, departement_id, departement_code, departement_texte)
|
|
SELECT
|
|
t_codes_postaux.oid,
|
|
t_codes_postaux.code,
|
|
t_codes_postaux.texte,
|
|
t_codes_postaux.texte_court,
|
|
t_codes_postaux.longitude,
|
|
t_codes_postaux.latitude,
|
|
t_codes_postaux.departement_id,
|
|
t_codes_postaux.departement_code,
|
|
t_codes_postaux.departement_texte
|
|
FROM base.t_codes_postaux
|
|
LEFT JOIN rh.t_codes_postaux t_codes_postaux_rh ON t_codes_postaux_rh.oid = t_codes_postaux.oid
|
|
WHERE t_codes_postaux_rh.oid IS NULL
|
|
;
|
|
|
|
UPDATE rh.t_codes_postaux t_codes_postaux_rh
|
|
SET
|
|
code = t_codes_postaux.code,
|
|
texte = t_codes_postaux.texte,
|
|
texte_court = t_codes_postaux.texte_court,
|
|
longitude = t_codes_postaux.longitude,
|
|
latitude = t_codes_postaux.latitude,
|
|
departement_id = t_codes_postaux.departement_id,
|
|
departement_code = t_codes_postaux.departement_code,
|
|
departement_texte = t_codes_postaux.departement_texte
|
|
FROM base.t_codes_postaux
|
|
WHERE 1=1
|
|
AND t_codes_postaux_rh.oid = t_codes_postaux.oid
|
|
AND (1!=1
|
|
OR t_codes_postaux_rh.code IS DISTINCT FROM t_codes_postaux.code
|
|
OR t_codes_postaux_rh.texte IS DISTINCT FROM t_codes_postaux.texte
|
|
OR t_codes_postaux_rh.texte_court IS DISTINCT FROM t_codes_postaux.texte_court
|
|
OR t_codes_postaux_rh.longitude IS DISTINCT FROM t_codes_postaux.longitude
|
|
OR t_codes_postaux_rh.latitude IS DISTINCT FROM t_codes_postaux.latitude
|
|
OR t_codes_postaux_rh.departement_id IS DISTINCT FROM t_codes_postaux.departement_id
|
|
OR t_codes_postaux_rh.departement_code IS DISTINCT FROM t_codes_postaux.departement_code
|
|
OR t_codes_postaux_rh.departement_texte IS DISTINCT FROM t_codes_postaux.departement_texte)
|
|
;
|
|
|
|
-- Màj des Depts.
|
|
DELETE
|
|
FROM rh.t_departements t_departements_rh
|
|
USING base.t_departements
|
|
WHERE t_departements_rh.oid = t_departements.oid AND
|
|
t_departements_rh.code <> t_departements.code
|
|
;
|
|
|
|
INSERT INTO rh.t_departements(oid, code, texte, texte_court)
|
|
SELECT
|
|
t_departements.oid,
|
|
t_departements.code,
|
|
t_departements.texte,
|
|
t_departements.texte_court
|
|
FROM base.t_departements
|
|
LEFT JOIN rh.t_departements t_departements_rh ON t_departements_rh.oid = t_departements.oid
|
|
WHERE t_departements_rh.oid IS NULL
|
|
;
|
|
|
|
UPDATE rh.t_departements t_departements_rh
|
|
SET
|
|
code = t_departements.code,
|
|
texte = t_departements.texte,
|
|
texte_court = t_departements.texte_court
|
|
FROM base.t_departements
|
|
WHERE
|
|
t_departements_rh.oid = t_departements.oid
|
|
AND (
|
|
t_departements_rh.code IS DISTINCT FROM t_departements.code OR
|
|
t_departements_rh.texte IS DISTINCT FROM t_departements.texte OR
|
|
t_departements_rh.texte_court IS DISTINCT FROM t_departements.texte_court
|
|
)
|
|
;
|
|
|
|
-- Màj des Entreprises
|
|
INSERT INTO rh.t_entreprises(oid, code_original, code, texte, texte_court)
|
|
SELECT 0, '', chr(1) || '*', 'Non renseignée', 'N/R'
|
|
WHERE 0 NOT IN (SELECT oid FROM rh.t_entreprises)
|
|
;
|
|
|
|
-- Màj des Etablissements
|
|
INSERT INTO rh.t_etablissements(oid, code_original, code, texte, texte_court, entreprise_id)
|
|
SELECT 0, '', chr(1) || '*', 'Non renseignée', 'N/R', 0
|
|
WHERE 0 NOT IN (SELECT oid FROM rh.t_etablissements)
|
|
;
|
|
|
|
-- Màj des "Catégories socio-professionnelles".
|
|
INSERT INTO rh.t_categories_socio_professionnelle(oid, code_original, code, texte, texte_court)
|
|
SELECT 0, '', chr(1) || '*', 'Non renseignée', 'N/R'
|
|
WHERE 0 NOT IN (SELECT oid FROM rh.t_categories_socio_professionnelle)
|
|
;
|
|
|
|
-- Màj des "Groupes de cotisants".
|
|
INSERT INTO rh.t_groupes_cotisant(oid, code_original, code, texte, texte_court)
|
|
SELECT 0, '', chr(1) || '*', 'Non renseigné', 'N/R'
|
|
WHERE 0 NOT IN (SELECT oid FROM rh.t_groupes_cotisant)
|
|
;
|
|
|
|
-- Màj des motifs de début de contrat.
|
|
INSERT INTO rh.t_motifs_debut_contrat(oid, code_original, code, texte, texte_court)
|
|
SELECT 0, '', chr(1) || '*', 'Non renseigné', 'N/R'
|
|
WHERE 0 NOT IN (SELECT oid FROM rh.t_motifs_debut_contrat)
|
|
;
|
|
|
|
-- Màj des motifs de fin de contrat.
|
|
INSERT INTO rh.t_motifs_fin_contrat(oid, code_original, code, texte, texte_court)
|
|
SELECT 0, '', chr(1) || '*', 'Non renseigné', 'N/R'
|
|
WHERE 0 NOT IN (SELECT oid FROM rh.t_motifs_fin_contrat)
|
|
;
|
|
|
|
-- Màj des motifs de fin de contrat : motif fictif CTI positionné lorsque contrat toujours en cours.
|
|
INSERT INTO rh.t_motifs_fin_contrat(code_original, code, texte, texte_court)
|
|
SELECT 'CTI_CNT_EC', 'CTI_CNT_EC', 'Contrat en cours', 'Contrat en cours'
|
|
WHERE 'CTI_CNT_EC' NOT IN (SELECT code_original FROM rh.t_motifs_fin_contrat)
|
|
;
|
|
|
|
-- Màj des "Nationalités".
|
|
INSERT INTO rh.t_nationalites(oid, code_original, code, texte, texte_court)
|
|
SELECT 0, '', chr(1) || '*', 'Non renseignée', 'N/R'
|
|
WHERE 0 NOT IN (SELECT oid FROM rh.t_nationalites)
|
|
;
|
|
|
|
-- Màj des "Organismes de cotisation".
|
|
INSERT INTO rh.t_organismes_cotisation(oid, code_original, code, texte, texte_court)
|
|
SELECT 0, '', chr(1) || '*', 'Non renseignée', 'N/R'
|
|
WHERE 0 NOT IN (SELECT oid FROM rh.t_organismes_cotisation)
|
|
;
|
|
|
|
-- Màj des "Unités Fonctionnelles".
|
|
INSERT INTO rh.t_unite_fonctionnelle(oid, code_original, code, texte, texte_court)
|
|
SELECT 0, '', chr(1) || '*', 'Non renseignée', 'N/R'
|
|
WHERE 0 NOT IN (SELECT oid FROM rh.t_unite_fonctionnelle)
|
|
;
|
|
|
|
-- Màj des "Rubriques".
|
|
INSERT INTO rh.t_rubriques(oid, code_original, code, texte, texte_court, rang_edition)
|
|
SELECT 0, '', chr(1) || '*', 'Non renseignée', 'N/R', 0
|
|
WHERE 0 NOT IN (SELECT oid FROM rh.t_rubriques)
|
|
;
|
|
|
|
-- (création des rubriques CTI de cumul).
|
|
INSERT INTO rh.t_rubriques(code, texte, texte_court, code_original, rang_edition)
|
|
SELECT 'C000', 'Ecart cumulé', 'Ecart cumulé', 'C000', -1
|
|
WHERE 'C000' NOT IN (SELECT code_original FROM rh.t_rubriques) AND
|
|
'C000' NOT IN (SELECT code FROM rh.t_rubriques)
|
|
;
|
|
|
|
-- Màj des situations de famille.
|
|
INSERT INTO rh.t_situations_famille(oid, code_original, code, texte, texte_court)
|
|
SELECT 0, '', chr(1) || '*', 'Non renseignée', 'N/R'
|
|
WHERE 0 NOT IN (SELECT oid FROM rh.t_situations_famille)
|
|
;
|
|
|
|
-- Màj des "Types de contrat".
|
|
INSERT INTO rh.t_types_contrat(oid, code_original, code, texte, texte_court)
|
|
SELECT 0, '', chr(1) || '*', 'Non renseigné', 'N/R'
|
|
WHERE 0 NOT IN (SELECT oid FROM rh.t_types_contrat)
|
|
;
|
|
|
|
-- Màj des "Statuts".
|
|
INSERT INTO rh.t_statuts(oid, code_original, code, texte, texte_court)
|
|
SELECT 0, '', chr(1) || '*', 'Non renseigné', 'N/R'
|
|
WHERE 0 NOT IN (SELECT oid FROM rh.t_statuts)
|
|
;
|
|
|
|
-- Màj des types de temps de travail.
|
|
INSERT INTO rh.t_types_temps_travail(oid, code_original, code, texte, texte_court)
|
|
SELECT 0, '', chr(1) || '*', 'Non renseigné', 'N/R'
|
|
WHERE 0 NOT IN (SELECT oid FROM rh.t_types_temps_travail)
|
|
;
|
|
|
|
-- Màj des "Services".
|
|
INSERT INTO rh.t_services(oid, code_original, code, texte, texte_court)
|
|
SELECT 0, '', chr(1) || '*', 'Non renseigné', 'N/R'
|
|
WHERE 0 NOT IN (SELECT oid FROM rh.t_services)
|
|
;
|
|
|
|
-- Màj des "Qualifications".
|
|
INSERT INTO rh.t_qualifications(oid, code_original, code, texte, texte_court)
|
|
SELECT 0, '', chr(1) || '*', 'Non renseigné', 'N/R'
|
|
WHERE 0 NOT IN (SELECT oid FROM rh.t_qualifications)
|
|
;
|
|
|
|
-- Màj des "Spécialités".
|
|
INSERT INTO rh.t_specialites(oid, code_original, code, texte, texte_court)
|
|
SELECT 0, '', chr(1) || '*', 'Non renseignée', 'N/R'
|
|
WHERE 0 NOT IN (SELECT oid FROM rh.t_specialites)
|
|
;
|
|
|
|
-- Màj des "Lettres Budgétaires".
|
|
INSERT INTO rh.t_lettre_budgetaire(oid, code_original, code, texte, texte_court)
|
|
SELECT 0, '', chr(1) || '*', 'Non renseignée', 'N/R'
|
|
WHERE 0 NOT IN (SELECT oid FROM rh.t_lettre_budgetaire)
|
|
;
|
|
|
|
-- Màj des "Codes emploi".
|
|
INSERT INTO rh.t_codes_emploi(oid, code_original, code, texte, texte_court)
|
|
SELECT 0, '', chr(1) || '*', 'Non renseigné', 'N/R'
|
|
WHERE 0 NOT IN (SELECT oid FROM rh.t_codes_emploi)
|
|
;
|
|
|
|
-- Màj des types d'horaire.
|
|
INSERT INTO rh.t_types_horaire(oid, code_original, code, texte, texte_court)
|
|
SELECT 0, '', chr(1) || '*', 'Non renseigné', 'N/R'
|
|
WHERE 0 NOT IN (SELECT oid FROM rh.t_types_horaire)
|
|
;
|
|
|
|
-- Màj des "Groupes de commission paritaire".
|
|
INSERT INTO rh.t_commission_paritaire(oid, code_original, code, texte, texte_court)
|
|
SELECT 0, '', chr(1) || '*', 'Non renseigné', 'N/R'
|
|
WHERE 0 NOT IN (SELECT oid FROM rh.t_commission_paritaire)
|
|
;
|
|
|
|
-- Màj des grilles.
|
|
INSERT INTO rh.t_grilles(oid, code_original, code, texte, texte_court)
|
|
SELECT 0, '', chr(1) || '*', 'Non renseignée', 'N/R'
|
|
WHERE 0 NOT IN (SELECT oid FROM rh.t_grilles)
|
|
;
|
|
|
|
-- Màj des groupes de grilles.
|
|
INSERT INTO rh.t_grilles_groupes(oid, code_original, code, texte, texte_court)
|
|
SELECT 0, '', chr(1) || '*', 'Non renseigné', 'N/R'
|
|
WHERE 0 NOT IN (SELECT oid FROM rh.t_grilles_groupes)
|
|
;
|
|
|
|
-- Màj des motifs d'arret.
|
|
INSERT INTO rh.t_motifs_arret(oid, code_original, code, texte, texte_court)
|
|
SELECT 0, '', chr(1) || '*', 'Non renseigné', 'N/R'
|
|
WHERE 0 NOT IN (SELECT oid FROM rh.t_motifs_arret)
|
|
;
|
|
|
|
-- Màj des précisions du motif d'arrêt.
|
|
INSERT INTO rh.t_precisions_motif_arret(oid, code_original, code, texte, texte_court)
|
|
SELECT 0, '', chr(1) || '*', 'Non renseignée', 'N/R'
|
|
WHERE 0 NOT IN (SELECT oid FROM rh.t_precisions_motif_arret)
|
|
;
|
|
|
|
-- Màj des "Motifs de visite médicale".
|
|
INSERT INTO rh.t_motifs_visite(oid, code_original, code, texte, texte_court)
|
|
SELECT 0, '', chr(1) || '*', 'Non renseigné', 'N/R'
|
|
WHERE 0 NOT IN (SELECT oid FROM rh.t_motifs_visite)
|
|
;
|
|
|
|
-- Màj des "Circonstances d'accident du travail".
|
|
INSERT INTO rh.t_accident_circonstance(oid, code_original, code, texte, texte_court)
|
|
SELECT 0, '', chr(1) || '*', 'Non renseigné', 'N/R'
|
|
WHERE 0 NOT IN (SELECT oid FROM rh.t_accident_circonstance)
|
|
;
|
|
|
|
-- Màj des "Lieux d'accident du travail".
|
|
INSERT INTO rh.t_accident_lieu(oid, code_original, code, texte, texte_court)
|
|
SELECT 0, '', chr(1) || '*', 'Non renseigné', 'N/R'
|
|
WHERE 0 NOT IN (SELECT oid FROM rh.t_accident_lieu)
|
|
;
|
|
|
|
-- Màj de la nature de l'accident du travail.
|
|
INSERT INTO rh.t_accident_nature(oid, code_original, code, texte, texte_court)
|
|
SELECT 0, '', chr(1) || '*', 'Non renseigné', 'N/R'
|
|
WHERE 0 NOT IN (SELECT oid FROM rh.t_accident_nature)
|
|
;
|
|
|
|
-- Màj des sièges d'accident du travail.
|
|
INSERT INTO rh.t_accident_siege(oid, code_original, code, texte, texte_court)
|
|
SELECT 0, '', chr(1) || '*', 'Non renseigné', 'N/R'
|
|
WHERE 0 NOT IN (SELECT oid FROM rh.t_accident_siege)
|
|
;
|
|
|
|
-- Màj des listes de formations.
|
|
INSERT INTO rh.t_liste_formations(oid, code_original, code, texte, texte_court)
|
|
SELECT 0, '', chr(1) || '*', 'Non renseigné', 'N/R'
|
|
WHERE 0 NOT IN (SELECT oid FROM rh.t_liste_formations)
|
|
;
|
|
|
|
-- Màj des comptes.
|
|
INSERT INTO rh.t_compte(oid, code_original, code, texte, texte_court)
|
|
SELECT 0, '', chr(1) || '*', 'Non renseigné', 'N/R'
|
|
WHERE 0 NOT IN (SELECT oid FROM rh.t_compte)
|
|
;
|
|
|
|
-- Màj des "Catégories de congé".
|
|
INSERT INTO rh.t_categorie_conge(oid, code_original, code, texte, texte_court)
|
|
SELECT 0, '', chr(1) || '*', 'Non renseigné', 'N/R'
|
|
WHERE 0 NOT IN (SELECT oid FROM rh.t_categorie_conge)
|
|
;
|
|
|
|
-- Màj des "Cadres d'emploi".
|
|
INSERT INTO rh.t_cadre_emploi(oid, code_original, code, texte, texte_court)
|
|
SELECT 0, '', chr(1) || '*', 'Non renseigné', 'N/R'
|
|
WHERE 0 NOT IN (SELECT oid FROM rh.t_cadre_emploi)
|
|
;
|
|
|
|
-- Màj des "Filières".
|
|
INSERT INTO rh.t_filiere(oid, code_original, code, texte, texte_court)
|
|
SELECT 0, '', chr(1) || '*', 'Non renseigné', 'N/R'
|
|
WHERE 0 NOT IN (SELECT oid FROM rh.t_filiere)
|
|
;
|
|
|
|
-- Màj des "Catégories statutaires".
|
|
INSERT INTO rh.t_categorie_statutaire(oid, code_original, code, texte, texte_court)
|
|
SELECT 0, '', chr(1) || '*', 'Non renseigné', 'N/R'
|
|
WHERE 0 NOT IN (SELECT oid FROM rh.t_categorie_statutaire)
|
|
;
|
|
|
|
-- Màj des "Codes cotisation".
|
|
INSERT INTO rh.t_code_cotisation(oid, code_original, code, texte, texte_court)
|
|
SELECT 0, '', chr(1) || '*', 'Non renseigné', 'N/R'
|
|
WHERE 0 NOT IN (SELECT oid FROM rh.t_code_cotisation)
|
|
;
|
|
|
|
-- Sections analytiques niveau 1
|
|
INSERT INTO rh.t_sections_analytiques_paie(oid, code_original, code, texte, texte_court)
|
|
SELECT 0, '', chr(127) || '*', 'Non renseignée', 'N/R'
|
|
WHERE 0 NOT IN (SELECT oid FROM rh.t_sections_analytiques_paie)
|
|
;
|
|
|
|
INSERT INTO rh.t_sections_analytiques(oid, code_original, code, texte, texte_court)
|
|
SELECT 0, '', chr(127) || '*', 'Non renseignée', 'N/R'
|
|
WHERE 0 NOT IN (SELECT oid FROM rh.t_sections_analytiques)
|
|
;
|
|
|
|
INSERT INTO rh.t_section_analytique(oid, code_original, code, texte, texte_court)
|
|
SELECT 0, '', chr(127) || '*', 'Non renseignée', 'N/R'
|
|
WHERE 0 NOT IN (SELECT oid FROM rh.t_section_analytique)
|
|
;
|
|
|
|
-- Pôles
|
|
INSERT INTO rh.t_pole(oid, code, texte, texte_court)
|
|
SELECT 0, chr(127) || '*', 'Non renseigné', 'N/R'
|
|
WHERE 0 NOT IN (SELECT oid FROM rh.t_pole)
|
|
;
|
|
|
|
-- Populations.
|
|
INSERT INTO rh.t_population(oid, code, texte, texte_court)
|
|
SELECT 0, chr(127) || '*', 'Non renseignée', 'N/R'
|
|
WHERE 0 NOT IN (SELECT oid FROM rh.t_population)
|
|
;
|
|
|
|
]]></sqlcmd>
|
|
</NODE>
|
|
</NODE>
|
|
<NODE name="PROFIL">
|
|
<!--
|
|
/*
|
|
Cette màj a un paramètre : w_profils.
|
|
De plus, w_profils doit avoir une colonne "profil_id" qui est renseigné à l'issu de cette section SQL.
|
|
*/
|
|
-->
|
|
<NODE label="Mise à jour des profils">
|
|
<sqlcmd><![CDATA[
|
|
|
|
-- RAZ des profils
|
|
TRUNCATE rh.p_profils
|
|
;
|
|
|
|
ALTER SEQUENCE rh.s_profils RESTART WITH 1
|
|
;
|
|
|
|
-- Désactivation des contraintes/index
|
|
SELECT base.cti_stash_table_constraints('rh.p_profils')
|
|
;
|
|
|
|
SELECT base.cti_stash_table_indexes('rh.p_profils')
|
|
;
|
|
|
|
-- Alimentation de la table CTI des profils
|
|
INSERT INTO rh.p_profils
|
|
(
|
|
cadre_emploi_code_original,
|
|
categorie_conge_code_original,
|
|
categorie_socio_professionnelle_code_original,
|
|
categorie_statutaire_code_original,
|
|
code_emploi_code_original,
|
|
commission_paritaire_code_original,
|
|
compte_salarie_code_original,
|
|
filiere_code_original,
|
|
grille_code_original,
|
|
grille_groupe_code_original,
|
|
groupe_cotisant_code_original,
|
|
lettre_budgetaire_code_original,
|
|
motif_debut_code_original,
|
|
motif_fin_code_original,
|
|
qualification_code_original,
|
|
section_analytique_code_original,
|
|
section_analytique_paie_code_original,
|
|
service_code_original,
|
|
societe_interim_code_original,
|
|
specialite_code_original,
|
|
statut_code_original,
|
|
type_contrat_code_original,
|
|
type_horaire_code_original,
|
|
type_temps_travail_code_original,
|
|
unite_fonctionnelle_code_original
|
|
)
|
|
SELECT
|
|
w_profils.cadre_emploi_code_original,
|
|
w_profils.categorie_conge_code_original,
|
|
w_profils.categorie_socio_professionnelle_code_original,
|
|
w_profils.categorie_statutaire_code_original,
|
|
w_profils.code_emploi_code_original,
|
|
w_profils.commission_paritaire_code_original,
|
|
w_profils.compte_salarie_code_original,
|
|
w_profils.filiere_code_original,
|
|
w_profils.grille_code_original,
|
|
w_profils.grille_groupe_code_original,
|
|
w_profils.groupe_cotisant_code_original,
|
|
w_profils.lettre_budgetaire_code_original,
|
|
w_profils.motif_debut_code_original,
|
|
w_profils.motif_fin_code_original,
|
|
w_profils.qualification_code_original,
|
|
w_profils.section_analytique_code_original,
|
|
w_profils.section_analytique_paie_code_original,
|
|
w_profils.service_code_original,
|
|
w_profils.societe_interim_code_original,
|
|
w_profils.specialite_code_original,
|
|
w_profils.statut_code_original,
|
|
w_profils.type_contrat_code_original,
|
|
w_profils.type_horaire_code_original,
|
|
w_profils.type_temps_travail_code_original,
|
|
w_profils.unite_fonctionnelle_code_original
|
|
FROM w_profils
|
|
GROUP BY 1,2,3,4,5,6,7,8,9,10,11,12,13,14,15,16,17,18,19,20,21,22,23,24,25
|
|
;
|
|
|
|
-- Insertion du profil N/R avec l'oid 0.
|
|
INSERT INTO rh.p_profils
|
|
(
|
|
oid,
|
|
cadre_emploi_code_original,
|
|
categorie_conge_code_original,
|
|
categorie_socio_professionnelle_code_original,
|
|
categorie_statutaire_code_original,
|
|
code_emploi_code_original,
|
|
commission_paritaire_code_original,
|
|
compte_salarie_code_original,
|
|
filiere_code_original,
|
|
grille_code_original,
|
|
grille_groupe_code_original,
|
|
groupe_cotisant_code_original,
|
|
lettre_budgetaire_code_original,
|
|
motif_debut_code_original,
|
|
motif_fin_code_original,
|
|
qualification_code_original,
|
|
section_analytique_code_original,
|
|
section_analytique_paie_code_original,
|
|
service_code_original,
|
|
societe_interim_code_original,
|
|
specialite_code_original,
|
|
statut_code_original,
|
|
type_contrat_code_original,
|
|
type_horaire_code_original,
|
|
type_temps_travail_code_original,
|
|
unite_fonctionnelle_code_original
|
|
)
|
|
SELECT
|
|
0,
|
|
chr(1)||'*',
|
|
chr(1)||'*',
|
|
chr(1)||'*',
|
|
chr(1)||'*',
|
|
chr(1)||'*',
|
|
chr(1)||'*',
|
|
chr(1)||'*',
|
|
chr(1)||'*',
|
|
chr(1)||'*',
|
|
chr(1)||'*',
|
|
chr(1)||'*',
|
|
chr(1)||'*',
|
|
chr(1)||'*',
|
|
chr(1)||'*',
|
|
chr(1)||'*',
|
|
chr(1)||'*',
|
|
chr(1)||'*',
|
|
chr(1)||'*',
|
|
chr(1)||'*',
|
|
chr(1)||'*',
|
|
chr(1)||'*',
|
|
chr(1)||'*',
|
|
chr(1)||'*',
|
|
chr(1)||'*',
|
|
chr(1)||'*'
|
|
;
|
|
|
|
-- Màj les oids et textes des profils
|
|
SELECT rh.cti_reorganize_profils()
|
|
;
|
|
|
|
-- Re-activation des contraintes/index
|
|
SELECT base.cti_stash_pop_table_indexes('rh.p_profils')
|
|
;
|
|
|
|
SELECT base.cti_stash_pop_table_constraints('rh.p_profils')
|
|
;
|
|
|
|
-- Màj des profil_id dans la table temporaire
|
|
UPDATE w_profils
|
|
SET profil_id = p_profils.oid
|
|
FROM rh.p_profils
|
|
WHERE 1=1
|
|
AND p_profils.cadre_emploi_code_original = w_profils.cadre_emploi_code_original
|
|
AND p_profils.categorie_conge_code_original = w_profils.categorie_conge_code_original
|
|
AND p_profils.categorie_socio_professionnelle_code_original = w_profils.categorie_socio_professionnelle_code_original
|
|
AND p_profils.categorie_statutaire_code_original = w_profils.categorie_statutaire_code_original
|
|
AND p_profils.code_emploi_code_original = w_profils.code_emploi_code_original
|
|
AND p_profils.commission_paritaire_code_original = w_profils.commission_paritaire_code_original
|
|
AND p_profils.compte_salarie_code_original = w_profils.compte_salarie_code_original
|
|
AND p_profils.filiere_code_original = w_profils.filiere_code_original
|
|
AND p_profils.grille_code_original = w_profils.grille_code_original
|
|
AND p_profils.grille_groupe_code_original = w_profils.grille_groupe_code_original
|
|
AND p_profils.groupe_cotisant_code_original = w_profils.groupe_cotisant_code_original
|
|
AND p_profils.lettre_budgetaire_code_original = w_profils.lettre_budgetaire_code_original
|
|
AND p_profils.motif_debut_code_original = w_profils.motif_debut_code_original
|
|
AND p_profils.motif_fin_code_original = w_profils.motif_fin_code_original
|
|
AND p_profils.qualification_code_original = w_profils.qualification_code_original
|
|
AND p_profils.section_analytique_code_original = w_profils.section_analytique_code_original
|
|
AND p_profils.section_analytique_paie_code_original = w_profils.section_analytique_paie_code_original
|
|
AND p_profils.service_code_original = w_profils.service_code_original
|
|
AND p_profils.societe_interim_code_original = w_profils.societe_interim_code_original
|
|
AND p_profils.specialite_code_original = w_profils.specialite_code_original
|
|
AND p_profils.statut_code_original = w_profils.statut_code_original
|
|
AND p_profils.type_contrat_code_original = w_profils.type_contrat_code_original
|
|
AND p_profils.type_horaire_code_original = w_profils.type_horaire_code_original
|
|
AND p_profils.type_temps_travail_code_original = w_profils.type_temps_travail_code_original
|
|
AND p_profils.unite_fonctionnelle_code_original = w_profils.unite_fonctionnelle_code_original
|
|
;
|
|
|
|
SELECT base.cti_optimize_table('w_profils')
|
|
;
|
|
|
|
]]></sqlcmd>
|
|
</NODE>
|
|
</NODE>
|
|
<NODE name="SALARIE">
|
|
<!-- Cette màj a un paramètre : w_salaries. -->
|
|
<NODE label="Pre-traitements de w_salaries (date d'ancienneté)">
|
|
<condition><![CDATA[
|
|
|
|
-- Si la table w_salaries n'a pas de colonne date_anciennete, on la rajoute à la volée.
|
|
select count(*) = 0
|
|
from information_schema.columns
|
|
where 1=1
|
|
and table_schema = (SELECT nspname FROM pg_namespace WHERE oid = pg_my_temp_schema())
|
|
and table_name = 'w_salaries'
|
|
and column_name = 'date_anciennete'
|
|
;
|
|
|
|
]]></condition>
|
|
<sqlcmd><![CDATA[
|
|
|
|
-- Création de la colonne.
|
|
ALTER TABLE w_salaries ADD COLUMN date_anciennete date;
|
|
|
|
-- Alimentation de la colonne.
|
|
UPDATE w_salaries SET
|
|
date_anciennete = date_entree_ets
|
|
;
|
|
|
|
]]></sqlcmd>
|
|
</NODE>
|
|
<NODE label="Pre-traitements de w_salaries (nir ou n° de sécu. soc.)">
|
|
<condition><![CDATA[
|
|
|
|
-- Si la table w_salaries n'a pas de colonne nir, on la rajoute à la volée.
|
|
select count(*) = 0
|
|
from information_schema.columns
|
|
where 1=1
|
|
and table_schema = (SELECT nspname FROM pg_namespace WHERE oid = pg_my_temp_schema())
|
|
and table_name = 'w_salaries'
|
|
and column_name = 'nir'
|
|
;
|
|
|
|
]]></condition>
|
|
<sqlcmd><![CDATA[
|
|
|
|
-- Création de la colonne.
|
|
ALTER TABLE w_salaries ADD COLUMN nir text;
|
|
|
|
]]></sqlcmd>
|
|
</NODE>
|
|
<NODE label="Pre-traitements de w_salaries (matricule planning)">
|
|
<condition><![CDATA[
|
|
|
|
-- Si la table w_salaries n'a pas de colonne matricule_planning, on la rajoute à la volée.
|
|
select count(*) = 0
|
|
from information_schema.columns
|
|
where 1=1
|
|
and table_schema = (SELECT nspname FROM pg_namespace WHERE oid = pg_my_temp_schema())
|
|
and table_name = 'w_salaries'
|
|
and column_name = 'matricule_planning'
|
|
;
|
|
|
|
]]></condition>
|
|
<sqlcmd><![CDATA[
|
|
|
|
-- Création de la colonne.
|
|
ALTER TABLE w_salaries ADD COLUMN matricule_planning text;
|
|
|
|
-- Alimentation de la colonne.
|
|
UPDATE w_salaries SET
|
|
matricule_planning = ''
|
|
;
|
|
|
|
]]></sqlcmd>
|
|
</NODE>
|
|
<NODE label="Pre-traitements de w_salaries (adresse1)">
|
|
<condition><![CDATA[
|
|
|
|
-- Si la table w_salaries n'a pas de colonne adresse1, on la rajoute à la volée.
|
|
select count(*) = 0
|
|
from information_schema.columns
|
|
where 1=1
|
|
and table_schema = (SELECT nspname FROM pg_namespace WHERE oid = pg_my_temp_schema())
|
|
and table_name = 'w_salaries'
|
|
and column_name = 'adresse1'
|
|
;
|
|
|
|
]]></condition>
|
|
<sqlcmd><![CDATA[
|
|
|
|
-- Création de la colonne.
|
|
ALTER TABLE w_salaries ADD COLUMN adresse1 text;
|
|
|
|
-- Alimentation de la colonne.
|
|
UPDATE w_salaries SET
|
|
adresse1 = ''
|
|
;
|
|
|
|
]]></sqlcmd>
|
|
</NODE>
|
|
<NODE label="Pre-traitements de w_salaries (adresse2)">
|
|
<condition><![CDATA[
|
|
|
|
-- Si la table w_salaries n'a pas de colonne adresse2, on la rajoute à la volée.
|
|
select count(*) = 0
|
|
from information_schema.columns
|
|
where 1=1
|
|
and table_schema = (SELECT nspname FROM pg_namespace WHERE oid = pg_my_temp_schema())
|
|
and table_name = 'w_salaries'
|
|
and column_name = 'adresse2'
|
|
;
|
|
|
|
]]></condition>
|
|
<sqlcmd><![CDATA[
|
|
|
|
-- Création de la colonne.
|
|
ALTER TABLE w_salaries ADD COLUMN adresse2 text;
|
|
|
|
-- Alimentation de la colonne.
|
|
UPDATE w_salaries SET
|
|
adresse2 = ''
|
|
;
|
|
|
|
]]></sqlcmd>
|
|
</NODE>
|
|
<NODE label="Mise à jour des salariés">
|
|
<sqlcmd><![CDATA[
|
|
|
|
-- Ajout des nouveaux salariés.
|
|
INSERT INTO rh.p_salaries(
|
|
finess,
|
|
nom,
|
|
prenom,
|
|
date_naissance,
|
|
sexe,
|
|
matricule,
|
|
matricule_planning,
|
|
code,
|
|
code_original,
|
|
nir,
|
|
entreprise_id,
|
|
nationalite_id,
|
|
code_postal_id,
|
|
nom_naissance,
|
|
situation_famille_id,
|
|
profil_id,
|
|
date_debut,
|
|
date_fin,
|
|
date_entree_ets,
|
|
date_sortie_ets,
|
|
date_anciennete,
|
|
date_entree_fp,
|
|
date_entree_fph,
|
|
no_adeli,
|
|
code_cotisation_id,
|
|
matricule_retraite,
|
|
adresse1,
|
|
adresse2
|
|
)
|
|
SELECT
|
|
finess,
|
|
nom,
|
|
prenom,
|
|
date_naissance,
|
|
sexe,
|
|
matricule,
|
|
matricule_planning,
|
|
code,
|
|
code_original,
|
|
nir,
|
|
entreprise_id,
|
|
nationalite_id,
|
|
code_postal_id,
|
|
nom_naissance,
|
|
situation_famille_id,
|
|
profil_id,
|
|
date_debut,
|
|
date_fin,
|
|
date_entree_ets,
|
|
date_sortie_ets,
|
|
date_anciennete,
|
|
date_entree_fp,
|
|
date_entree_fph,
|
|
no_adeli,
|
|
code_cotisation_id,
|
|
matricule_retraite,
|
|
adresse1,
|
|
adresse2
|
|
FROM w_salaries
|
|
WHERE code_original NOT IN (SELECT code_original FROM rh.p_salaries)
|
|
;
|
|
|
|
-- Màj de ceux déjà en BD.
|
|
UPDATE rh.p_salaries
|
|
SET
|
|
finess = w_salaries.finess,
|
|
nom = w_salaries.nom,
|
|
prenom = w_salaries.prenom,
|
|
date_naissance = w_salaries.date_naissance,
|
|
sexe = w_salaries.sexe,
|
|
matricule = w_salaries.matricule,
|
|
matricule_planning = w_salaries.matricule_planning,
|
|
code = w_salaries.code,
|
|
--code_original,
|
|
nir = w_salaries.nir,
|
|
entreprise_id = w_salaries.entreprise_id,
|
|
nationalite_id = w_salaries.nationalite_id,
|
|
code_postal_id = w_salaries.code_postal_id,
|
|
nom_naissance = w_salaries.nom_naissance,
|
|
situation_famille_id = w_salaries.situation_famille_id,
|
|
profil_id = w_salaries.profil_id,
|
|
date_debut = w_salaries.date_debut,
|
|
date_fin = w_salaries.date_fin,
|
|
date_entree_ets = w_salaries.date_entree_ets,
|
|
date_sortie_ets = w_salaries.date_sortie_ets,
|
|
date_anciennete = w_salaries.date_anciennete,
|
|
date_entree_fp = w_salaries.date_entree_fp,
|
|
date_entree_fph = w_salaries.date_entree_fph,
|
|
no_adeli = w_salaries.no_adeli,
|
|
code_cotisation_id = w_salaries.code_cotisation_id,
|
|
matricule_retraite = w_salaries.matricule_retraite,
|
|
adresse1 = w_salaries.adresse1,
|
|
adresse2 = w_salaries.adresse2
|
|
FROM w_salaries
|
|
WHERE 1=1
|
|
AND p_salaries.code_original = w_salaries.code_original
|
|
AND (1!=1
|
|
OR p_salaries.finess IS DISTINCT FROM w_salaries.finess
|
|
OR p_salaries.nom IS DISTINCT FROM w_salaries.nom
|
|
OR p_salaries.prenom IS DISTINCT FROM w_salaries.prenom
|
|
OR p_salaries.date_naissance IS DISTINCT FROM w_salaries.date_naissance
|
|
OR p_salaries.sexe IS DISTINCT FROM w_salaries.sexe
|
|
OR p_salaries.matricule IS DISTINCT FROM w_salaries.matricule
|
|
OR p_salaries.matricule_planning IS DISTINCT FROM w_salaries.matricule_planning
|
|
OR p_salaries.code IS DISTINCT FROM w_salaries.code
|
|
OR p_salaries.nir IS DISTINCT FROM w_salaries.nir
|
|
OR p_salaries.entreprise_id IS DISTINCT FROM w_salaries.entreprise_id
|
|
OR p_salaries.nationalite_id IS DISTINCT FROM w_salaries.nationalite_id
|
|
OR p_salaries.code_postal_id IS DISTINCT FROM w_salaries.code_postal_id
|
|
OR p_salaries.nom_naissance IS DISTINCT FROM w_salaries.nom_naissance
|
|
OR p_salaries.situation_famille_id IS DISTINCT FROM w_salaries.situation_famille_id
|
|
OR p_salaries.profil_id IS DISTINCT FROM w_salaries.profil_id
|
|
OR p_salaries.date_debut IS DISTINCT FROM w_salaries.date_debut
|
|
OR p_salaries.date_fin IS DISTINCT FROM w_salaries.date_fin
|
|
OR p_salaries.date_entree_ets IS DISTINCT FROM w_salaries.date_entree_ets
|
|
OR p_salaries.date_sortie_ets IS DISTINCT FROM w_salaries.date_sortie_ets
|
|
OR p_salaries.date_anciennete IS DISTINCT FROM w_salaries.date_anciennete
|
|
OR p_salaries.date_entree_fp IS DISTINCT FROM w_salaries.date_entree_fp
|
|
OR p_salaries.date_entree_fph IS DISTINCT FROM w_salaries.date_entree_fph
|
|
OR p_salaries.no_adeli IS DISTINCT FROM w_salaries.no_adeli
|
|
OR p_salaries.code_cotisation_id IS DISTINCT FROM w_salaries.code_cotisation_id
|
|
OR p_salaries.matricule_retraite IS DISTINCT FROM w_salaries.matricule_retraite
|
|
OR p_salaries.adresse1 IS DISTINCT FROM w_salaries.adresse1
|
|
OR p_salaries.adresse2 IS DISTINCT FROM w_salaries.adresse2
|
|
)
|
|
;
|
|
|
|
]]></sqlcmd>
|
|
</NODE>
|
|
</NODE>
|
|
<NODE name="PROD_COMMON" label="">
|
|
<NODE label="Pré-traitements">
|
|
<sqlcmd><![CDATA[
|
|
|
|
-- Init table spécialités si non alimentée
|
|
CREATE TABLE IF NOT EXISTS temp.x_ref_specialite
|
|
(
|
|
code text,
|
|
code_original text,
|
|
texte text,
|
|
texte_court text
|
|
)
|
|
;
|
|
CREATE TABLE IF NOT EXISTS temp.x_hst_specialite AS
|
|
SELECT
|
|
null::text as ety_code_original,
|
|
null::text as sal_code_original,
|
|
null::text as cnt_code_original,
|
|
null::date as date_effet,
|
|
null::text as specialite_code_original
|
|
limit 0
|
|
;
|
|
|
|
|
|
DROP TABLE IF EXISTS w_cnt_sal
|
|
;
|
|
|
|
CREATE TEMP TABLE w_cnt_sal AS
|
|
with dates_0 as (
|
|
select
|
|
ety_code_original,
|
|
sal_code_original,
|
|
cnt_code_original,
|
|
date_debut as date_effet,
|
|
0 as est_hors_periode
|
|
from temp.x_hst_contrat
|
|
union
|
|
select
|
|
ety_code_original,
|
|
sal_code_original,
|
|
cnt_code_original,
|
|
date_fin as date_effet,
|
|
0 as est_hors_periode
|
|
from temp.x_hst_contrat
|
|
union
|
|
select
|
|
ety_code_original,
|
|
sal_code_original,
|
|
cnt_code_original,
|
|
date_debut as date_effet,
|
|
est_hors_periode
|
|
from temp.x_hst_bulletin
|
|
union
|
|
select
|
|
ety_code_original,
|
|
sal_code_original,
|
|
cnt_code_original,
|
|
date_fin as date_effet,
|
|
est_hors_periode
|
|
from temp.x_hst_bulletin
|
|
union
|
|
select
|
|
ety_code_original,
|
|
sal_code_original,
|
|
cnt_code_original,
|
|
date_effet,
|
|
null::integer
|
|
from temp.x_hst_categorie_socio_professionnelle
|
|
union
|
|
select
|
|
ety_code_original,
|
|
sal_code_original,
|
|
cnt_code_original,
|
|
date_effet,
|
|
null::integer
|
|
from temp.x_hst_motif_debut_contrat
|
|
union
|
|
select
|
|
ety_code_original,
|
|
sal_code_original,
|
|
cnt_code_original,
|
|
date_effet,
|
|
null::integer
|
|
from temp.x_hst_motif_fin_contrat
|
|
union
|
|
select
|
|
ety_code_original,
|
|
sal_code_original,
|
|
cnt_code_original,
|
|
date_effet,
|
|
null::integer
|
|
from temp.x_hst_type_contrat
|
|
union
|
|
select
|
|
ety_code_original,
|
|
sal_code_original,
|
|
cnt_code_original,
|
|
date_effet,
|
|
null::integer
|
|
from temp.x_hst_qualification
|
|
union
|
|
select
|
|
ety_code_original,
|
|
sal_code_original,
|
|
cnt_code_original,
|
|
date_effet,
|
|
null::integer
|
|
from temp.x_hst_statut
|
|
union
|
|
select
|
|
ety_code_original,
|
|
sal_code_original,
|
|
cnt_code_original,
|
|
date_effet,
|
|
null::integer
|
|
from temp.x_hst_type_temps_travail
|
|
union
|
|
select
|
|
ety_code_original,
|
|
sal_code_original,
|
|
cnt_code_original,
|
|
date_effet,
|
|
null::integer
|
|
from temp.x_hst_service
|
|
union
|
|
select
|
|
ety_code_original,
|
|
sal_code_original,
|
|
cnt_code_original,
|
|
date_effet,
|
|
null::integer
|
|
from temp.x_hst_specialite
|
|
union
|
|
select
|
|
ety_code_original,
|
|
sal_code_original,
|
|
cnt_code_original,
|
|
date_effet,
|
|
null::integer
|
|
from temp.x_hst_code_emploi
|
|
union
|
|
select
|
|
ety_code_original,
|
|
sal_code_original,
|
|
cnt_code_original,
|
|
date_effet,
|
|
null::integer
|
|
from temp.x_hst_etp_contrat
|
|
union
|
|
select
|
|
ety_code_original,
|
|
sal_code_original,
|
|
cnt_code_original,
|
|
date_effet,
|
|
null::integer
|
|
from temp.x_hst_grille
|
|
)
|
|
, dates as (
|
|
select
|
|
ety_code_original,
|
|
sal_code_original,
|
|
cnt_code_original,
|
|
date_effet,
|
|
max(coalesce(est_hors_periode, 0)) as est_hors_periode
|
|
from dates_0
|
|
group by 1,2,3,4
|
|
)
|
|
, raw_data_0 as(
|
|
select
|
|
dates.ety_code_original,
|
|
dates.sal_code_original,
|
|
dates.cnt_code_original,
|
|
dates.date_effet,
|
|
est_hors_periode::text,
|
|
x_hst_etp_contrat.etp_contrat,
|
|
x_hst_categorie_socio_professionnelle.categorie_socio_professionnelle_code_original,
|
|
x_hst_motif_debut_contrat.motif_debut_code_original,
|
|
x_hst_motif_fin_contrat.motif_fin_code_original,
|
|
x_hst_type_contrat.type_contrat_code_original,
|
|
x_hst_qualification.qualification_code_original,
|
|
x_hst_statut.statut_code_original,
|
|
x_hst_type_temps_travail.type_temps_travail_code_original,
|
|
x_hst_service.service_code_original,
|
|
x_hst_specialite.specialite_code_original,
|
|
x_hst_code_emploi.code_emploi_code_original,
|
|
x_hst_grille.grille_code_original
|
|
from dates
|
|
left join temp.x_hst_etp_contrat on 1=1
|
|
and x_hst_etp_contrat.sal_code_original = dates.sal_code_original
|
|
and x_hst_etp_contrat.date_effet = dates.date_effet
|
|
left join temp.x_hst_categorie_socio_professionnelle on 1=1
|
|
and x_hst_categorie_socio_professionnelle.sal_code_original = dates.sal_code_original
|
|
and x_hst_categorie_socio_professionnelle.date_effet = dates.date_effet
|
|
left join temp.x_hst_motif_debut_contrat on 1=1
|
|
and x_hst_motif_debut_contrat.sal_code_original = dates.sal_code_original
|
|
and x_hst_motif_debut_contrat.date_effet = dates.date_effet
|
|
left join temp.x_hst_motif_fin_contrat on 1=1
|
|
and x_hst_motif_fin_contrat.sal_code_original = dates.sal_code_original
|
|
and x_hst_motif_fin_contrat.date_effet = dates.date_effet
|
|
left join temp.x_hst_type_contrat on 1=1
|
|
and x_hst_type_contrat.sal_code_original = dates.sal_code_original
|
|
and x_hst_type_contrat.date_effet = dates.date_effet
|
|
left join temp.x_hst_qualification on 1=1
|
|
and x_hst_qualification.sal_code_original = dates.sal_code_original
|
|
and x_hst_qualification.date_effet = dates.date_effet
|
|
left join temp.x_hst_statut on 1=1
|
|
and x_hst_statut.sal_code_original = dates.sal_code_original
|
|
and x_hst_statut.date_effet = dates.date_effet
|
|
left join temp.x_hst_type_temps_travail on 1=1
|
|
and x_hst_type_temps_travail.sal_code_original = dates.sal_code_original
|
|
and x_hst_type_temps_travail.date_effet = dates.date_effet
|
|
left join temp.x_hst_service on 1=1
|
|
and x_hst_service.sal_code_original = dates.sal_code_original
|
|
and x_hst_service.date_effet = dates.date_effet
|
|
left join temp.x_hst_specialite on 1=1
|
|
and x_hst_specialite.sal_code_original = dates.sal_code_original
|
|
and x_hst_specialite.date_effet = dates.date_effet
|
|
left join temp.x_hst_code_emploi on 1=1
|
|
and x_hst_code_emploi.sal_code_original = dates.sal_code_original
|
|
and x_hst_code_emploi.date_effet = dates.date_effet
|
|
left join temp.x_hst_grille on 1=1
|
|
and x_hst_grille.sal_code_original = dates.sal_code_original
|
|
and x_hst_grille.date_effet = dates.date_effet
|
|
)
|
|
, raw_data_1 as(
|
|
select
|
|
ety_code_original,
|
|
sal_code_original,
|
|
cnt_code_original,
|
|
date_effet,
|
|
est_hors_periode,
|
|
coalesce(etp_contrat, -- si la valeur est renseignée sur la ligne courante, on la prend.
|
|
(max(case when etp_contrat is null then null else ARRAY[extract(epoch from date_effet), etp_contrat] end) over wb)[2] -- sinon on prend la valeur renseignée la plus proche dans le passé
|
|
) as etp_contrat,
|
|
coalesce(categorie_socio_professionnelle_code_original, -- si la valeur est renseignée sur la ligne courante, on la prend.
|
|
(max(case when categorie_socio_professionnelle_code_original is null then null else ARRAY[to_char(date_effet, 'YYYYMMDD'), categorie_socio_professionnelle_code_original] end) over wb)[2] -- sinon on prend la valeur renseignée la plus proche dans le passé
|
|
) as categorie_socio_professionnelle_code_original,
|
|
coalesce(motif_debut_code_original, -- si la valeur est renseignée sur la ligne courante, on la prend.
|
|
(max(case when motif_debut_code_original is null then null else ARRAY[to_char(date_effet, 'YYYYMMDD'), motif_debut_code_original] end) over wb)[2] -- sinon on prend la valeur renseignée la plus proche dans le passé
|
|
) as motif_debut_code_original,
|
|
coalesce(motif_fin_code_original, -- si la valeur est renseignée sur la ligne courante, on la prend.
|
|
(max(case when motif_fin_code_original is null then null else ARRAY[to_char(date_effet, 'YYYYMMDD'), motif_fin_code_original] end) over wb)[2] -- sinon on prend la valeur renseignée la plus proche dans le passé
|
|
) as motif_fin_code_original,
|
|
coalesce(type_contrat_code_original, -- si la valeur est renseignée sur la ligne courante, on la prend.
|
|
(max(case when type_contrat_code_original is null then null else ARRAY[to_char(date_effet, 'YYYYMMDD'), type_contrat_code_original] end) over wb)[2] -- sinon on prend la valeur renseignée la plus proche dans le passé
|
|
) as type_contrat_code_original,
|
|
coalesce(qualification_code_original, -- si la valeur est renseignée sur la ligne courante, on la prend.
|
|
(max(case when qualification_code_original is null then null else ARRAY[to_char(date_effet, 'YYYYMMDD'), qualification_code_original] end) over wb)[2] -- sinon on prend la valeur renseignée la plus proche dans le passé
|
|
) as qualification_code_original,
|
|
coalesce(statut_code_original, -- si la valeur est renseignée sur la ligne courante, on la prend.
|
|
(max(case when statut_code_original is null then null else ARRAY[to_char(date_effet, 'YYYYMMDD'), statut_code_original] end) over wb)[2] -- sinon on prend la valeur renseignée la plus proche dans le passé
|
|
) as statut_code_original,
|
|
coalesce(type_temps_travail_code_original, -- si la valeur est renseignée sur la ligne courante, on la prend.
|
|
(max(case when type_temps_travail_code_original is null then null else ARRAY[to_char(date_effet, 'YYYYMMDD'), type_temps_travail_code_original] end) over wb)[2] -- sinon on prend la valeur renseignée la plus proche dans le passé
|
|
) as type_temps_travail_code_original,
|
|
coalesce(service_code_original, -- si la valeur est renseignée sur la ligne courante, on la prend.
|
|
(max(case when service_code_original is null then null else ARRAY[to_char(date_effet, 'YYYYMMDD'), service_code_original] end) over wb)[2] -- sinon on prend la valeur renseignée la plus proche dans le passé
|
|
) as service_code_original,
|
|
coalesce(specialite_code_original, -- si la valeur est renseignée sur la ligne courante, on la prend.
|
|
(max(case when specialite_code_original is null then null else ARRAY[to_char(date_effet, 'YYYYMMDD'), specialite_code_original] end) over wb)[2] -- sinon on prend la valeur renseignée la plus proche dans le passé
|
|
) as specialite_code_original,
|
|
coalesce(code_emploi_code_original, -- si la valeur est renseignée sur la ligne courante, on la prend.
|
|
(max(case when code_emploi_code_original is null then null else ARRAY[to_char(date_effet, 'YYYYMMDD'), code_emploi_code_original] end) over wb)[2] -- sinon on prend la valeur renseignée la plus proche dans le passé
|
|
) as code_emploi_code_original,
|
|
coalesce(grille_code_original, -- si la valeur est renseignée sur la ligne courante, on la prend.
|
|
(max(case when grille_code_original is null then null else ARRAY[to_char(date_effet, 'YYYYMMDD'), grille_code_original] end) over wb)[2] -- sinon on prend la valeur renseignée la plus proche dans le passé
|
|
) as grille_code_original
|
|
from raw_data_0
|
|
window
|
|
wb as (PARTITION BY ety_code_original, sal_code_original ORDER BY date_effet rows unbounded preceding) -- sélectionne les lignes précédentes
|
|
)
|
|
, raw_data as(
|
|
select
|
|
ety_code_original,
|
|
sal_code_original,
|
|
cnt_code_original,
|
|
date_effet,
|
|
est_hors_periode::text,
|
|
coalesce(etp_contrat, -- si la valeur est renseignée sur la ligne courante, on la prend.
|
|
(min(case when etp_contrat is null then null else ARRAY[extract(epoch from date_effet), etp_contrat] end) over wf)[2], -- sinon on prend la valeur renseignée la plus proche dans le futur
|
|
1.0 -- sinon on prend 1. Ne devrait pas arriver.
|
|
) as etp_contrat,
|
|
coalesce(categorie_socio_professionnelle_code_original, -- si la valeur est renseignée sur la ligne courante, on la prend.
|
|
(min(case when categorie_socio_professionnelle_code_original is null then null else ARRAY[to_char(date_effet, 'YYYYMMDD'), categorie_socio_professionnelle_code_original] end) over wf)[2], -- sinon on prend la valeur renseignée la plus proche dans le futur
|
|
chr(1)||'*' -- sinon on prend N/R. Ne devrait pas arriver.
|
|
) as categorie_socio_professionnelle_code_original,
|
|
coalesce(motif_debut_code_original, -- si la valeur est renseignée sur la ligne courante, on la prend.
|
|
(min(case when motif_debut_code_original is null then null else ARRAY[to_char(date_effet, 'YYYYMMDD'), motif_debut_code_original] end) over wf)[2], -- sinon on prend la valeur renseignée la plus proche dans le futur
|
|
chr(1)||'*' -- sinon on prend N/R. Ne devrait pas arriver.
|
|
) as motif_debut_code_original,
|
|
coalesce(motif_fin_code_original, -- si la valeur est renseignée sur la ligne courante, on la prend.
|
|
(min(case when motif_fin_code_original is null then null else ARRAY[to_char(date_effet, 'YYYYMMDD'), motif_fin_code_original] end) over wf)[2], -- sinon on prend la valeur renseignée la plus proche dans le futur
|
|
chr(1)||'*' -- sinon on prend N/R. Ne devrait pas arriver.
|
|
) as motif_fin_code_original,
|
|
coalesce(type_contrat_code_original, -- si la valeur est renseignée sur la ligne courante, on la prend.
|
|
(min(case when type_contrat_code_original is null then null else ARRAY[to_char(date_effet, 'YYYYMMDD'), type_contrat_code_original] end) over wf)[2], -- sinon on prend la valeur renseignée la plus proche dans le futur
|
|
chr(1)||'*' -- sinon on prend N/R. Ne devrait pas arriver.
|
|
) as type_contrat_code_original,
|
|
coalesce(qualification_code_original, -- si la valeur est renseignée sur la ligne courante, on la prend.
|
|
(min(case when qualification_code_original is null then null else ARRAY[to_char(date_effet, 'YYYYMMDD'), qualification_code_original] end) over wf)[2], -- sinon on prend la valeur renseignée la plus proche dans le futur
|
|
chr(1)||'*' -- sinon on prend N/R. Ne devrait pas arriver.
|
|
) as qualification_code_original,
|
|
coalesce(statut_code_original, -- si la valeur est renseignée sur la ligne courante, on la prend.
|
|
(min(case when statut_code_original is null then null else ARRAY[to_char(date_effet, 'YYYYMMDD'), statut_code_original] end) over wf)[2], -- sinon on prend la valeur renseignée la plus proche dans le futur
|
|
chr(1)||'*' -- sinon on prend N/R. Ne devrait pas arriver.
|
|
) as statut_code_original,
|
|
coalesce(type_temps_travail_code_original, -- si la valeur est renseignée sur la ligne courante, on la prend.
|
|
(min(case when type_temps_travail_code_original is null then null else ARRAY[to_char(date_effet, 'YYYYMMDD'), type_temps_travail_code_original] end) over wf)[2], -- sinon on prend la valeur renseignée la plus proche dans le futur
|
|
chr(1)||'*' -- sinon on prend N/R. Ne devrait pas arriver.
|
|
) as type_temps_travail_code_original,
|
|
coalesce(service_code_original, -- si la valeur est renseignée sur la ligne courante, on la prend.
|
|
(min(case when service_code_original is null then null else ARRAY[to_char(date_effet, 'YYYYMMDD'), service_code_original] end) over wf)[2], -- sinon on prend la valeur renseignée la plus proche dans le futur
|
|
chr(1)||'*' -- sinon on prend N/R. Ne devrait pas arriver.
|
|
) as service_code_original,
|
|
coalesce(specialite_code_original, -- si la valeur est renseignée sur la ligne courante, on la prend.
|
|
(min(case when specialite_code_original is null then null else ARRAY[to_char(date_effet, 'YYYYMMDD'), specialite_code_original] end) over wf)[2], -- sinon on prend la valeur renseignée la plus proche dans le futur
|
|
chr(1)||'*' -- sinon on prend N/R. Ne devrait pas arriver.
|
|
) as specialite_code_original,
|
|
coalesce(code_emploi_code_original, -- si la valeur est renseignée sur la ligne courante, on la prend.
|
|
(min(case when code_emploi_code_original is null then null else ARRAY[to_char(date_effet, 'YYYYMMDD'), code_emploi_code_original] end) over wf)[2], -- sinon on prend la valeur renseignée la plus proche dans le futur
|
|
chr(1)||'*' -- sinon on prend N/R. Ne devrait pas arriver.
|
|
) as code_emploi_code_original,
|
|
coalesce(grille_code_original, -- si la valeur est renseignée sur la ligne courante, on la prend.
|
|
(min(case when grille_code_original is null then null else ARRAY[to_char(date_effet, 'YYYYMMDD'), grille_code_original] end) over wf)[2], -- sinon on prend la valeur renseignée la plus proche dans le futur
|
|
chr(1)||'*' -- sinon on prend N/R. Ne devrait pas arriver.
|
|
) as grille_code_original
|
|
from raw_data_1
|
|
window
|
|
wf as (PARTITION BY ety_code_original, sal_code_original ORDER BY date_effet desc rows unbounded preceding) -- sélectionne les lignes suivantes
|
|
)
|
|
, clustering as (
|
|
select
|
|
ety_code_original,
|
|
sal_code_original,
|
|
cnt_code_original,
|
|
est_hors_periode,
|
|
etp_contrat,
|
|
date_effet,
|
|
categorie_socio_professionnelle_code_original,
|
|
motif_debut_code_original,
|
|
motif_fin_code_original,
|
|
type_contrat_code_original,
|
|
qualification_code_original,
|
|
statut_code_original,
|
|
type_temps_travail_code_original,
|
|
service_code_original,
|
|
specialite_code_original,
|
|
code_emploi_code_original,
|
|
grille_code_original,
|
|
case when
|
|
lag(
|
|
categorie_socio_professionnelle_code_original||
|
|
motif_debut_code_original||
|
|
motif_fin_code_original||
|
|
type_contrat_code_original||
|
|
qualification_code_original||
|
|
statut_code_original||
|
|
type_temps_travail_code_original||
|
|
service_code_original||
|
|
specialite_code_original||
|
|
code_emploi_code_original||
|
|
cnt_code_original||
|
|
est_hors_periode||
|
|
grille_code_original||
|
|
etp_contrat::text
|
|
) over w
|
|
= categorie_socio_professionnelle_code_original||
|
|
motif_debut_code_original||
|
|
motif_fin_code_original||
|
|
type_contrat_code_original||
|
|
qualification_code_original||
|
|
statut_code_original||
|
|
type_temps_travail_code_original||
|
|
service_code_original||
|
|
specialite_code_original||
|
|
code_emploi_code_original||
|
|
cnt_code_original||
|
|
est_hors_periode||
|
|
grille_code_original||
|
|
etp_contrat::text
|
|
then null else true end as new_cluster
|
|
from raw_data
|
|
window w as (partition by ety_code_original, sal_code_original order by date_effet)
|
|
)
|
|
, assigned_clustering as (
|
|
select
|
|
ety_code_original,
|
|
sal_code_original,
|
|
cnt_code_original,
|
|
est_hors_periode,
|
|
etp_contrat,
|
|
date_effet,
|
|
categorie_socio_professionnelle_code_original,
|
|
motif_debut_code_original,
|
|
motif_fin_code_original,
|
|
type_contrat_code_original,
|
|
qualification_code_original,
|
|
statut_code_original,
|
|
type_temps_travail_code_original,
|
|
service_code_original,
|
|
specialite_code_original,
|
|
code_emploi_code_original,
|
|
grille_code_original,
|
|
to_char(date_effet, 'YYYYMM')::int as mois,
|
|
count(new_cluster) over (order by ety_code_original, sal_code_original, date_effet rows unbounded preceding) as cluster_id
|
|
from clustering
|
|
)
|
|
select
|
|
ety_code_original,
|
|
sal_code_original,
|
|
cnt_code_original,
|
|
est_hors_periode,
|
|
etp_contrat,
|
|
categorie_socio_professionnelle_code_original,
|
|
motif_debut_code_original,
|
|
motif_fin_code_original,
|
|
type_contrat_code_original,
|
|
qualification_code_original,
|
|
statut_code_original,
|
|
type_temps_travail_code_original,
|
|
service_code_original,
|
|
specialite_code_original,
|
|
code_emploi_code_original,
|
|
grille_code_original,
|
|
mois,
|
|
min(date_effet) AS date_debut,
|
|
max(date_effet) AS date_fin,
|
|
cluster_id
|
|
from assigned_clustering
|
|
group by 1,2,3,4,5,6,7,8,9,10,11,12,13,14,15,16,17, cluster_id
|
|
;
|
|
|
|
]]></sqlcmd>
|
|
</NODE>
|
|
<NODE name="INIT" type="common" />
|
|
<NODE label="Màj des entreprises/établissements">
|
|
<sqlcmd><![CDATA[
|
|
|
|
-- Màj des Entreprises.
|
|
INSERT INTO rh.t_entreprises(code_original, code, texte, texte_court)
|
|
SELECT
|
|
code_original,
|
|
code,
|
|
texte,
|
|
coalesce(texte_court, substr(texte, 1, 50))
|
|
FROM temp.x_ref_ent
|
|
WHERE code_original NOT IN (SELECT code_original FROM rh.t_entreprises)
|
|
;
|
|
|
|
-- Màj des Etablissements.
|
|
INSERT INTO rh.t_etablissements(code_original, code, texte, texte_court, entreprise_id)
|
|
SELECT
|
|
x_ref_ets.code_original,
|
|
x_ref_ets.code,
|
|
x_ref_ets.texte,
|
|
coalesce(x_ref_ets.texte_court, substr(x_ref_ets.texte, 1, 50)),
|
|
t_entreprises.oid
|
|
FROM temp.x_ref_ets
|
|
JOIN rh.t_entreprises ON t_entreprises.code_original = x_ref_ets.ent_code_original
|
|
WHERE x_ref_ets.code_original NOT IN (SELECT code_original FROM rh.t_etablissements)
|
|
;
|
|
|
|
]]></sqlcmd>
|
|
</NODE>
|
|
<NODE label="Màj des informations permanentes">
|
|
<sqlcmd><![CDATA[
|
|
|
|
-- Màj des Catégories Socio-Professionnelles.
|
|
INSERT INTO rh.t_categories_socio_professionnelle (code_original, code, texte, texte_court)
|
|
SELECT code_original, code, texte, coalesce(texte_court, substr(texte, 1, 50))
|
|
FROM temp.x_ref_categorie_socio_professionnelle
|
|
WHERE code_original NOT IN (SELECT code_original FROM rh.t_categories_socio_professionnelle)
|
|
;
|
|
|
|
-- Màj des Nationalités.
|
|
INSERT INTO rh.t_nationalites(code_original, code, texte, texte_court)
|
|
SELECT code_original, code, texte, coalesce(texte_court, substr(texte, 1, 50))
|
|
FROM temp.x_ref_nationalite
|
|
WHERE code_original NOT IN (SELECT code_original FROM rh.t_nationalites)
|
|
;
|
|
|
|
-- Màj des motifs de début de contrat.
|
|
INSERT INTO rh.t_motifs_debut_contrat(code_original, code, texte, texte_court)
|
|
SELECT code_original, code, texte, coalesce(texte_court, substr(texte, 1, 50))
|
|
FROM temp.x_ref_motif_debut_contrat
|
|
WHERE code_original NOT IN (SELECT code_original FROM rh.t_motifs_debut_contrat)
|
|
;
|
|
|
|
-- Màj des motifs de fin de contrat.
|
|
INSERT INTO rh.t_motifs_fin_contrat(code_original, code, texte, texte_court)
|
|
SELECT code_original, code, texte, coalesce(texte_court, substr(texte, 1, 50))
|
|
FROM temp.x_ref_motif_fin_contrat
|
|
WHERE code_original NOT IN (SELECT code_original FROM rh.t_motifs_fin_contrat)
|
|
;
|
|
|
|
-- Màj des types de contrat.
|
|
INSERT INTO rh.t_types_contrat(code_original, code, texte, texte_court)
|
|
SELECT code_original, code, texte, coalesce(texte_court, substr(texte, 1, 50))
|
|
FROM temp.x_ref_type_contrat
|
|
WHERE code_original NOT IN (SELECT code_original FROM rh.t_types_contrat)
|
|
;
|
|
|
|
-- Màj des groupes cotisants.
|
|
INSERT INTO rh.t_groupes_cotisant(code_original, code, texte, texte_court)
|
|
SELECT code_original, code, texte, coalesce(texte_court, substr(texte, 1, 50))
|
|
FROM temp.x_ref_groupe_cotisant
|
|
WHERE code_original NOT IN (SELECT code_original FROM rh.t_groupes_cotisant)
|
|
;
|
|
|
|
-- @TODO Màj des organismes de cotisation
|
|
|
|
-- Màj des qualifications
|
|
INSERT INTO rh.t_qualifications(code_original, code, texte, texte_court)
|
|
SELECT code_original, code, texte, coalesce(texte_court, substr(texte, 1, 50))
|
|
FROM temp.x_ref_qualification
|
|
WHERE code_original NOT IN (SELECT code_original FROM rh.t_qualifications)
|
|
;
|
|
|
|
-- @TODO Màj des Comptes
|
|
|
|
-- Màj des situations de famille
|
|
INSERT INTO rh.t_situations_famille(code_original, code, texte, texte_court)
|
|
SELECT code_original, code, texte, coalesce(texte_court, substr(texte, 1, 50))
|
|
FROM temp.x_ref_situation_famille
|
|
WHERE code_original NOT IN (SELECT code_original FROM rh.t_situations_famille)
|
|
;
|
|
|
|
-- Màj des statuts
|
|
INSERT INTO rh.t_statuts(code_original, code, texte, texte_court)
|
|
SELECT code_original, code, texte, coalesce(texte_court, substr(texte, 1, 50))
|
|
FROM temp.x_ref_statut
|
|
WHERE code_original NOT IN (SELECT code_original FROM rh.t_statuts)
|
|
;
|
|
|
|
-- Màj des types de temps de travail
|
|
INSERT INTO rh.t_types_temps_travail(code_original, code, texte, texte_court)
|
|
SELECT code_original, code, texte, coalesce(texte_court, substr(texte, 1, 50))
|
|
FROM temp.x_ref_type_temps_travail
|
|
WHERE code_original NOT IN (SELECT code_original FROM rh.t_types_temps_travail)
|
|
;
|
|
|
|
-- Màj des services
|
|
INSERT INTO rh.t_services(code_original, code, texte, texte_court)
|
|
SELECT code_original, code, texte, coalesce(texte_court, substr(texte, 1, 50))
|
|
FROM temp.x_ref_service
|
|
WHERE code_original NOT IN (SELECT code_original FROM rh.t_services)
|
|
;
|
|
|
|
-- Màj des spécialités
|
|
INSERT INTO rh.t_specialites(code_original, code, texte, texte_court)
|
|
SELECT code_original, code, texte, coalesce(texte_court, substr(texte, 1, 50))
|
|
FROM temp.x_ref_specialite
|
|
WHERE code_original NOT IN (SELECT code_original FROM rh.t_specialites)
|
|
;
|
|
|
|
-- Màj des codes emploi
|
|
INSERT INTO rh.t_codes_emploi(code_original, code, texte, texte_court)
|
|
SELECT code_original, code, texte, coalesce(texte_court, substr(texte, 1, 50))
|
|
FROM temp.x_ref_code_emploi
|
|
WHERE code_original NOT IN (SELECT code_original FROM rh.t_codes_emploi)
|
|
;
|
|
|
|
-- @TODO Màj des types d'horaire
|
|
|
|
-- Màj des grilles
|
|
INSERT INTO rh.t_grilles(code_original, code, texte, texte_court)
|
|
SELECT code_original, code, texte, coalesce(texte_court, substr(texte, 1, 50))
|
|
FROM temp.x_ref_grille
|
|
WHERE code_original NOT IN (SELECT code_original FROM rh.t_grilles)
|
|
;
|
|
|
|
-- @TODO Màj des groupes de grilles
|
|
|
|
-- @TODO Màj des motifs d'arret
|
|
|
|
-- @TODO Màj des précisions du motif d'arrêt
|
|
|
|
-- @TODO Màj des motifs de visite médicale
|
|
|
|
-- @TODO Màj des circonstances d'accident du travail
|
|
|
|
-- @TODO Màj des lieux d'accident du travail
|
|
|
|
-- @TODO Màj de la nature de l'accident du travail
|
|
|
|
-- @TODO Màj des sièges d'accident du travail
|
|
|
|
-- @TODO Màj des listes de formations
|
|
|
|
-- Màj des rubriques.
|
|
INSERT INTO rh.t_rubriques(code_original, code, texte, texte_court, rang_edition)
|
|
SELECT code_original, code, texte, coalesce(texte_court, substr(texte, 1, 50)), rang_edition
|
|
FROM temp.x_ref_rubrique
|
|
WHERE code_original NOT IN (SELECT code_original FROM rh.t_rubriques)
|
|
;
|
|
|
|
UPDATE rh.t_rubriques SET
|
|
code = x_ref_rubrique.code,
|
|
texte = x_ref_rubrique.texte,
|
|
texte_court = substr(x_ref_rubrique.texte,50)
|
|
FROM temp.x_ref_rubrique
|
|
WHERE t_rubriques.code_original = x_ref_rubrique.code_original AND
|
|
(
|
|
t_rubriques.code IS DISTINCT FROM x_ref_rubrique.code OR
|
|
t_rubriques.texte IS DISTINCT FROM x_ref_rubrique.texte OR
|
|
t_rubriques.texte_court IS DISTINCT FROM substr(x_ref_rubrique.texte,50)
|
|
)
|
|
;
|
|
|
|
-- Màj des comptes
|
|
CREATE TABLE IF NOT EXISTS temp.x_ref_compte (code_original text, code text, texte text, texte_court text)
|
|
;
|
|
INSERT INTO rh.t_compte(code_original, code, texte, texte_court)
|
|
SELECT code_original, code, texte, coalesce(CASE WHEN texte_court = '' THEN NULL ELSE texte_court END, substr(texte, 1, 50))
|
|
FROM temp.x_ref_compte
|
|
WHERE code_original NOT IN (SELECT code_original FROM rh.t_compte WHERE code_original IS NOT NULL)
|
|
;
|
|
|
|
]]></sqlcmd>
|
|
</NODE>
|
|
<NODE label="Paramétrage des rubriques">
|
|
<sqlcmd><![CDATA[
|
|
|
|
-- Pré-paramétrage automatique des rubriques (au mieux).
|
|
-- Cette requête n'intervient pas sur les rubriques paramétrées à la main.
|
|
update rh.t_rubriques
|
|
set
|
|
p_cumul = x_ref_rubrique.p_cumul,
|
|
p_detail = x_ref_rubrique.p_detail,
|
|
p_nombre = x_ref_rubrique.p_nombre,
|
|
s_nombre = x_ref_rubrique.s_nombre,
|
|
c_nombre = x_ref_rubrique.c_nombre,
|
|
p_base = x_ref_rubrique.p_base,
|
|
s_base = x_ref_rubrique.s_base,
|
|
c_base = x_ref_rubrique.c_base,
|
|
p_heures_contrat = x_ref_rubrique.p_heures_contrat,
|
|
s_heures_contrat = x_ref_rubrique.s_heures_contrat,
|
|
c_heures_contrat = x_ref_rubrique.c_heures_contrat,
|
|
p_heures_payees = x_ref_rubrique.p_heures_payees,
|
|
s_heures_payees = x_ref_rubrique.s_heures_payees,
|
|
c_heures_payees = x_ref_rubrique.c_heures_payees,
|
|
p_heures_travaillees = x_ref_rubrique.p_heures_travaillees,
|
|
s_heures_travaillees = x_ref_rubrique.s_heures_travaillees,
|
|
c_heures_travaillees = x_ref_rubrique.c_heures_travaillees,
|
|
p_masse_salariale = x_ref_rubrique.p_masse_salariale,
|
|
s_masse_salariale = x_ref_rubrique.s_masse_salariale,
|
|
c_masse_salariale = x_ref_rubrique.c_masse_salariale,
|
|
p_brut = x_ref_rubrique.p_brut,
|
|
s_brut = x_ref_rubrique.s_brut,
|
|
c_brut = x_ref_rubrique.c_brut,
|
|
p_avantage_nature = x_ref_rubrique.p_avantage_nature,
|
|
s_avantage_nature = x_ref_rubrique.s_avantage_nature,
|
|
c_avantage_nature = x_ref_rubrique.c_avantage_nature,
|
|
p_frais_imposables = x_ref_rubrique.p_frais_imposables,
|
|
s_frais_imposables = x_ref_rubrique.s_frais_imposables,
|
|
c_frais_imposables = x_ref_rubrique.c_frais_imposables,
|
|
p_cotisation_salarie = x_ref_rubrique.p_cotisation_salarie,
|
|
s_cotisation_salarie = x_ref_rubrique.s_cotisation_salarie,
|
|
c_cotisation_salarie = x_ref_rubrique.c_cotisation_salarie,
|
|
p_cotisation_patronale = x_ref_rubrique.p_cotisation_patronale,
|
|
s_cotisation_patronale = x_ref_rubrique.s_cotisation_patronale,
|
|
c_cotisation_patronale = x_ref_rubrique.c_cotisation_patronale,
|
|
p_od_net_salarie = x_ref_rubrique.p_od_net_salarie,
|
|
s_od_net_salarie = x_ref_rubrique.s_od_net_salarie,
|
|
c_od_net_salarie = x_ref_rubrique.c_od_net_salarie,
|
|
p_od_net_patronale = x_ref_rubrique.p_od_net_patronale,
|
|
s_od_net_patronale = x_ref_rubrique.s_od_net_patronale,
|
|
c_od_net_patronale = x_ref_rubrique.c_od_net_patronale,
|
|
p_net_imposable = x_ref_rubrique.p_net_imposable,
|
|
s_net_imposable = x_ref_rubrique.s_net_imposable,
|
|
c_net_imposable = x_ref_rubrique.c_net_imposable,
|
|
p_net_a_payer = x_ref_rubrique.p_net_a_payer,
|
|
s_net_a_payer = x_ref_rubrique.s_net_a_payer,
|
|
c_net_a_payer = x_ref_rubrique.c_net_a_payer
|
|
from temp.x_ref_rubrique
|
|
where 1=1
|
|
AND t_rubriques.code_original = x_ref_rubrique.code_original
|
|
AND NOT t_rubriques.user_modified
|
|
;
|
|
|
|
]]></sqlcmd>
|
|
</NODE>
|
|
<NODE label="Profils">
|
|
<sqlcmd><![CDATA[
|
|
|
|
DROP TABLE IF EXISTS w_profils
|
|
;
|
|
|
|
CREATE TEMP TABLE w_profils AS
|
|
with ets as (
|
|
select
|
|
t_entreprises.code_original||'-'||t_etablissements.code_original as code_original,
|
|
t_etablissements.oid as etablissement_id
|
|
from rh.t_entreprises
|
|
join rh.t_etablissements on t_etablissements.entreprise_id = t_entreprises.oid
|
|
)
|
|
select
|
|
row_number() over () as pro_id,
|
|
0::bigint AS profil_id,
|
|
0::bigint AS contrat_id,
|
|
0::bigint AS contrat_mois_id,
|
|
0::bigint AS salarie_id,
|
|
etablissement_id,
|
|
sal_code_original,
|
|
sal_code_original as matricule,
|
|
cnt_code_original,
|
|
est_hors_periode,
|
|
etp_contrat,
|
|
mois,
|
|
date_debut,
|
|
date_fin,
|
|
-- **** code original ****
|
|
categorie_socio_professionnelle_code_original,
|
|
code_emploi_code_original,
|
|
grille_code_original,
|
|
chr(1)||'*' AS grille_groupe_code_original,
|
|
chr(1)||'*' AS groupe_cotisant_code_original,
|
|
motif_debut_code_original,
|
|
motif_fin_code_original,
|
|
qualification_code_original,
|
|
chr(1)||'*' AS section_analytique_code_original,
|
|
chr(1)||'*' AS section_analytique_paie_code_original,
|
|
service_code_original,
|
|
chr(1)||'*' AS societe_interim_code_original,
|
|
specialite_code_original,
|
|
statut_code_original,
|
|
type_contrat_code_original,
|
|
chr(1)||'*' AS type_horaire_code_original,
|
|
type_temps_travail_code_original,
|
|
-- public
|
|
chr(1)||'*' AS cadre_emploi_code_original,
|
|
chr(1)||'*' AS categorie_conge_code_original,
|
|
chr(1)||'*' AS categorie_statutaire_code_original,
|
|
chr(1)||'*' AS commission_paritaire_code_original,
|
|
chr(1)||'*' AS compte_salarie_code_original,
|
|
chr(1)||'*' AS filiere_code_original,
|
|
chr(1)||'*' AS lettre_budgetaire_code_original,
|
|
chr(1)||'*' AS unite_fonctionnelle_code_original
|
|
from w_cnt_sal
|
|
join ets on ets.code_original = w_cnt_sal.ety_code_original
|
|
;
|
|
|
|
]]></sqlcmd>
|
|
</NODE>
|
|
<NODE name="PROFIL" type="common" />
|
|
<NODE label="Salariés">
|
|
<sqlcmd><![CDATA[
|
|
|
|
DROP TABLE IF EXISTS w_salaries
|
|
;
|
|
|
|
CREATE TEMP TABLE w_salaries AS
|
|
with last_profil as (
|
|
select
|
|
sal_code_original as lp_sal_code_original,
|
|
(max(array[extract(epoch from date_debut), profil_id]))[2] as lp_profil_id
|
|
from w_profils
|
|
group by 1
|
|
)
|
|
select
|
|
rhp('finess') AS finess,
|
|
nom,
|
|
nom_naissance,
|
|
prenom,
|
|
date_naissance,
|
|
sexe as sexe,
|
|
matricule,
|
|
x_ref_salarie.code,
|
|
x_ref_salarie.code_original,
|
|
x_ref_salarie.nir,
|
|
coalesce(t_entreprises.oid, 0::bigint) AS entreprise_id,
|
|
coalesce(t_nationalites.oid, 0::bigint) AS nationalite_id,
|
|
coalesce(t_codes_postaux.oid, 0::bigint) AS code_postal_id,
|
|
coalesce(t_situations_famille.oid, 0::bigint) AS situation_famille_id,
|
|
coalesce(last_profil.lp_profil_id, 0::bigint) AS profil_id,
|
|
date_debut,
|
|
date_fin,
|
|
date_entree_ets,
|
|
date_sortie_ets,
|
|
date_anciennete,
|
|
-- Champs dédiés au public.
|
|
date_entree_fp,
|
|
date_entree_fph,
|
|
no_adeli,
|
|
code_cotisation_id,
|
|
matricule_retraite,
|
|
adresse1,
|
|
adresse2
|
|
from temp.x_ref_salarie
|
|
left join last_profil on last_profil.lp_sal_code_original = x_ref_salarie.code_original
|
|
left join rh.t_codes_postaux ON t_codes_postaux.code = x_ref_salarie.code_postal
|
|
left join rh.t_situations_famille ON t_situations_famille.code_original = x_ref_salarie.situation_famille
|
|
left join rh.t_nationalites ON t_nationalites.code_original = x_ref_salarie.nationalite
|
|
left join rh.t_entreprises on t_entreprises.code_original = x_ref_salarie.entreprise
|
|
;
|
|
|
|
]]></sqlcmd>
|
|
</NODE>
|
|
<NODE name="SALARIE" type="common" />
|
|
<NODE label="Salariés (màj oid)">
|
|
<sqlcmd><![CDATA[
|
|
|
|
UPDATE w_profils
|
|
SET salarie_id = p_salaries.oid
|
|
FROM rh.p_salaries
|
|
WHERE w_profils.sal_code_original = p_salaries.code_original
|
|
;
|
|
|
|
]]></sqlcmd>
|
|
</NODE>
|
|
<NODE label="Contrats">
|
|
<sqlcmd><![CDATA[
|
|
|
|
TRUNCATE rh.p_contrats
|
|
;
|
|
|
|
ALTER SEQUENCE rh.s_contrats RESTART WITH 1
|
|
;
|
|
|
|
INSERT INTO rh.p_contrats(
|
|
salarie_id,
|
|
date_debut,
|
|
date_fin,
|
|
numero_contrat,
|
|
code_original,
|
|
etablissement_id,
|
|
profil_id)
|
|
SELECT
|
|
w_profils.salarie_id,
|
|
x_hst_contrat.date_debut,
|
|
x_hst_contrat.date_fin,
|
|
x_hst_contrat.numero_contrat,
|
|
x_hst_contrat.cnt_code_original AS code_original,
|
|
w_profils.etablissement_id,
|
|
(max(ARRAY[extract(EPOCH from w_profils.date_fin), w_profils.profil_id]))[2] as profil_id
|
|
FROM temp.x_hst_contrat
|
|
join w_profils on 1=1
|
|
and w_profils.cnt_code_original = x_hst_contrat.cnt_code_original
|
|
and w_profils.est_hors_periode = 0
|
|
group by 1,2,3,4,5,6
|
|
;
|
|
|
|
|
|
SELECT base.cti_stash_table_indexes('rh.p_contrats_mois')
|
|
;
|
|
|
|
TRUNCATE rh.p_contrats_mois
|
|
;
|
|
|
|
ALTER SEQUENCE rh.s_contrats_mois RESTART WITH 1
|
|
;
|
|
|
|
DROP TABLE IF EXISTS w_contrats_mois
|
|
;
|
|
|
|
CREATE TEMP TABLE w_contrats_mois AS
|
|
SELECT
|
|
pro_id,
|
|
nextval('rh.s_contrats_mois'::regclass) as contrat_mois_id,
|
|
p_contrats.salarie_id as salarie_id,
|
|
p_contrats.oid as contrat_id,
|
|
w_profils.mois as mois_activite,
|
|
w_profils.date_debut,
|
|
w_profils.date_fin,
|
|
CASE WHEN p_salaries.date_entree_ets BETWEEN w_profils.date_debut AND w_profils.date_fin THEN 1 ELSE 0 END AS nombre_entrees,
|
|
CASE WHEN p_salaries.date_sortie_ets BETWEEN w_profils.date_debut AND w_profils.date_fin THEN 1 ELSE 0 END AS nombre_departs,
|
|
CASE WHEN p_contrats.date_debut BETWEEN w_profils.date_debut AND w_profils.date_fin THEN 1 ELSE 0 END AS nombre_debut_contrat,
|
|
CASE WHEN p_contrats.date_fin BETWEEN w_profils.date_debut AND w_profils.date_fin THEN 1 ELSE 0 END AS nombre_fin_contrat,
|
|
w_profils.est_hors_periode,
|
|
CASE WHEN base.cti_first_day(w_profils.date_debut) BETWEEN p_contrats.date_debut AND p_contrats.date_fin THEN 1 ELSE 0 END AS present_debut_mois,
|
|
CASE WHEN base.cti_last_day(w_profils.date_fin) BETWEEN p_contrats.date_debut AND p_contrats.date_fin THEN 1 ELSE 0 END AS present_fin_mois,
|
|
case when w_profils.est_hors_periode = 0 IS NOT NULL
|
|
then w_profils.etp_contrat -- Il n'y a pas d'ETP contrat ni d'anciennetés pour les contrats_mois hors période.
|
|
* (
|
|
(w_profils.date_fin - w_profils.date_debut + 1)::numeric
|
|
/
|
|
(base.cti_last_day(to_date(w_profils.mois, 'YYYYMM')) - to_date(w_profils.mois, 'YYYYMM') + 1)::numeric
|
|
) else 0.0 end AS equivalent_temps_plein,
|
|
base.cti_age(w_profils.date_fin, p_salaries.date_naissance, 'ny') AS age_id,
|
|
w_profils.date_fin - p_salaries.date_naissance AS age_jours,
|
|
case when w_profils.est_hors_periode = 0 then p_contrats.anciennete_anterieure_jours
|
|
+ (w_profils.date_fin - p_contrats.date_debut)
|
|
+ 1
|
|
else 0 end AS anciennete_jours,
|
|
case when w_profils.est_hors_periode = 0 then base.cti_age(date_trunc('month', w_profils.date_fin::date)::date, date_trunc('month', p_contrats.date_debut)::date, 'nm')
|
|
+ greatest(p_contrats.anciennete_anterieure_mois, p_contrats.anciennete_anterieure_calculee_mois) + 1 else 0 end
|
|
AS anciennete_mois,
|
|
case when w_profils.est_hors_periode = 0 then floor((base.cti_age(date_trunc('month', w_profils.date_fin::date)::date, date_trunc('month', p_contrats.date_debut)::date, 'nm')
|
|
+ greatest(p_contrats.anciennete_anterieure_mois, p_contrats.anciennete_anterieure_calculee_mois) + 1) / 12) else 0 end
|
|
AS anciennete_annee_id,
|
|
w_profils.etablissement_id
|
|
FROM w_profils
|
|
join rh.p_salaries on p_salaries.code_original = w_profils.sal_code_original
|
|
join rh.p_contrats on p_contrats.code_original = w_profils.cnt_code_original
|
|
;
|
|
|
|
-- On renseigne les id de contrats de w_profils.
|
|
UPDATE w_profils SET
|
|
contrat_id = w_contrats_mois.contrat_id,
|
|
contrat_mois_id = w_contrats_mois.contrat_mois_id
|
|
FROM w_contrats_mois
|
|
WHERE w_profils.pro_id = w_contrats_mois.pro_id
|
|
;
|
|
|
|
INSERT INTO rh.p_contrats_mois(
|
|
oid,
|
|
salarie_id,
|
|
contrat_id,
|
|
mois_activite,
|
|
date_debut,
|
|
date_fin,
|
|
nombre_entrees,
|
|
nombre_departs,
|
|
nombre_debut_contrat,
|
|
nombre_fin_contrat,
|
|
est_hors_periode, -- bulletins de paie hors période de contrat.
|
|
present_debut_mois,
|
|
present_fin_mois,
|
|
equivalent_temps_plein,
|
|
age_id,
|
|
age_jours,
|
|
anciennete_jours,
|
|
anciennete_mois,
|
|
anciennete_annee_id,
|
|
etablissement_id)
|
|
SELECT
|
|
contrat_mois_id,
|
|
salarie_id,
|
|
contrat_id,
|
|
mois_activite,
|
|
date_debut,
|
|
date_fin,
|
|
nombre_entrees,
|
|
nombre_departs,
|
|
nombre_debut_contrat,
|
|
nombre_fin_contrat,
|
|
est_hors_periode,
|
|
present_debut_mois,
|
|
present_fin_mois,
|
|
equivalent_temps_plein,
|
|
age_id,
|
|
age_jours,
|
|
anciennete_jours,
|
|
anciennete_mois,
|
|
anciennete_annee_id,
|
|
etablissement_id
|
|
FROM w_contrats_mois
|
|
;
|
|
|
|
SELECT base.cti_stash_pop_table_indexes('rh.p_contrats_mois')
|
|
;
|
|
|
|
]]></sqlcmd>
|
|
</NODE>
|
|
<NODE label="Historique de la paie">
|
|
<sqlcmd><![CDATA[
|
|
|
|
ALTER TABLE temp.x_hst_paie ADD COLUMN IF NOT EXISTS cpt_code_original text
|
|
;
|
|
|
|
DROP TABLE IF EXISTS w_hp
|
|
;
|
|
|
|
CREATE TEMP TABLE w_hp AS
|
|
SELECT
|
|
x_hst_paie.bul_id,
|
|
w_profils.etablissement_id,
|
|
w_profils.salarie_id,
|
|
w_profils.sal_code_original,
|
|
w_profils.matricule AS matricule,
|
|
x_hst_paie.date_debut,
|
|
x_hst_paie.date_fin,
|
|
x_hst_paie.mois_activite,
|
|
x_hst_paie.date_paie,
|
|
x_hst_paie.mois_paie,
|
|
t_rubriques.oid AS rubrique_id,
|
|
0::bigint as organisme_cotisation_id,
|
|
COALESCE(t_compte.oid,0) AS compte_id,
|
|
--t_rubriques.code_original AS rub_code,
|
|
--t_rubriques.texte AS rub_texte,
|
|
t_rubriques.c_base
|
|
* case when @t_rubriques.c_base != 1 then coalesce(case when proratiser_conversion then w_profils.etp_contrat else 1.0 end, 1.0) else 1.0 end
|
|
* CASE WHEN p_base THEN (CASE s_base
|
|
WHEN 0 THEN base
|
|
WHEN 1 THEN base
|
|
WHEN 3 THEN mntsal
|
|
WHEN 5 THEN mntpat
|
|
END) else 0 end AS base,
|
|
t_rubriques.c_nombre
|
|
* case when @t_rubriques.c_nombre != 1 then coalesce(case when proratiser_conversion then w_profils.etp_contrat else 1.0 end, 1.0) else 1.0 end
|
|
* CASE WHEN p_nombre THEN (CASE s_nombre
|
|
WHEN 0 THEN base
|
|
WHEN 1 THEN base
|
|
WHEN 3 THEN mntsal
|
|
WHEN 5 THEN mntpat
|
|
END) else 0 end AS nombre,
|
|
t_rubriques.c_heures_contrat
|
|
* case when @t_rubriques.c_heures_contrat != 1 then coalesce(case when proratiser_conversion then w_profils.etp_contrat else 1.0 end, 1.0) else 1.0 end
|
|
* CASE WHEN p_heures_contrat
|
|
then (CASE s_heures_contrat
|
|
WHEN 0 THEN base
|
|
WHEN 1 THEN base
|
|
WHEN 3 THEN mntsal
|
|
WHEN 5 THEN mntpat
|
|
END)
|
|
else 0 end AS heure_contrat,
|
|
t_rubriques.c_heures_payees
|
|
* case when @t_rubriques.c_heures_payees != 1 then coalesce(case when proratiser_conversion then w_profils.etp_contrat else 1.0 end, 1.0) else 1.0 end
|
|
* CASE WHEN p_heures_payees
|
|
then (CASE s_heures_payees
|
|
WHEN 0 THEN base
|
|
WHEN 1 THEN base
|
|
WHEN 3 THEN mntsal
|
|
WHEN 5 THEN mntpat
|
|
END)
|
|
else 0 end AS heure_payee,
|
|
t_rubriques.c_heures_travaillees
|
|
* case when @t_rubriques.c_heures_travaillees != 1 then coalesce(case when proratiser_conversion then w_profils.etp_contrat else 1.0 end, 1.0) else 1.0 end
|
|
* CASE WHEN p_heures_travaillees
|
|
then (CASE s_heures_travaillees
|
|
WHEN 0 THEN base
|
|
WHEN 1 THEN base
|
|
WHEN 3 THEN mntsal
|
|
WHEN 5 THEN mntpat
|
|
END)
|
|
else 0 end AS heure_travaillee,
|
|
t_rubriques.c_masse_salariale *
|
|
CASE WHEN p_masse_salariale
|
|
THEN (CASE s_masse_salariale
|
|
WHEN 0 THEN base
|
|
WHEN 1 THEN base
|
|
WHEN 3 THEN mntsal
|
|
WHEN 5 THEN mntpat
|
|
END)
|
|
else 0 end AS montant_masse_salariale,
|
|
t_rubriques.c_brut *
|
|
CASE WHEN p_brut
|
|
THEN (CASE s_brut
|
|
WHEN 0 THEN base
|
|
WHEN 1 THEN base
|
|
WHEN 3 THEN mntsal
|
|
WHEN 5 THEN mntpat
|
|
END)
|
|
else 0 end AS montant_brut,
|
|
t_rubriques.c_frais_imposables *
|
|
case when p_frais_imposables
|
|
then (CASE s_frais_imposables
|
|
WHEN 0 THEN base
|
|
WHEN 1 THEN base
|
|
WHEN 3 THEN mntsal
|
|
WHEN 5 THEN mntpat
|
|
END)
|
|
else 0 end AS montant_frais_imposables,
|
|
t_rubriques.coefficient_txs *
|
|
case when p_cotisation_salarie
|
|
then txsal
|
|
else 0 end AS taux_cotisation_salarie,
|
|
t_rubriques.c_cotisation_salarie *
|
|
case when p_cotisation_salarie
|
|
then (CASE s_cotisation_salarie
|
|
WHEN 0 THEN base
|
|
WHEN 1 THEN base
|
|
WHEN 3 THEN mntsal
|
|
WHEN 5 THEN mntpat
|
|
END)
|
|
else 0 end AS montant_cotisation_salarie,
|
|
t_rubriques.coefficient_txp *
|
|
case when p_cotisation_patronale
|
|
then txpat
|
|
else 0 end AS taux_cotisation_patronale,
|
|
t_rubriques.c_cotisation_patronale *
|
|
case when p_cotisation_patronale
|
|
then (CASE s_cotisation_patronale
|
|
WHEN 0 THEN base
|
|
WHEN 1 THEN base
|
|
WHEN 3 THEN mntsal
|
|
WHEN 5 THEN mntpat
|
|
END)
|
|
else 0 end AS montant_cotisation_patronale,
|
|
t_rubriques.c_od_net_salarie *
|
|
CASE WHEN p_od_net_salarie
|
|
THEN (CASE s_od_net_salarie
|
|
WHEN 0 THEN base
|
|
WHEN 1 THEN base
|
|
WHEN 3 THEN mntsal
|
|
WHEN 5 THEN mntpat
|
|
END)
|
|
ELSE 0 END AS montant_od_net_salarie,
|
|
t_rubriques.c_od_net_patronale *
|
|
CASE WHEN p_od_net_patronale
|
|
THEN (CASE s_od_net_patronale
|
|
WHEN 0 THEN base
|
|
WHEN 1 THEN base
|
|
WHEN 3 THEN mntsal
|
|
WHEN 5 THEN mntpat
|
|
END)
|
|
ELSE 0 END AS montant_od_net_patronale,
|
|
t_rubriques.c_avantage_nature *
|
|
CASE WHEN p_avantage_nature
|
|
THEN (CASE s_avantage_nature
|
|
WHEN 0 THEN base
|
|
WHEN 1 THEN base
|
|
WHEN 3 THEN mntsal
|
|
WHEN 5 THEN mntpat
|
|
END)
|
|
ELSE 0 END AS montant_avantage_nature,
|
|
t_rubriques.c_net_imposable *
|
|
CASE WHEN p_net_imposable
|
|
THEN (CASE s_net_imposable
|
|
WHEN 0 THEN base
|
|
WHEN 1 THEN base
|
|
WHEN 3 THEN mntsal
|
|
WHEN 5 THEN mntpat
|
|
WHEN 6 THEN mntsal + mntpat
|
|
WHEN 7 THEN mntsal - mntpat
|
|
WHEN 8 THEN -mntsal + mntpat
|
|
END)
|
|
ELSE 0 END AS montant_net_imposable_salarie,
|
|
t_rubriques.c_net_a_payer *
|
|
CASE WHEN p_net_a_payer
|
|
THEN (CASE s_net_a_payer
|
|
WHEN 0 THEN base
|
|
WHEN 1 THEN base
|
|
WHEN 3 THEN mntsal
|
|
WHEN 5 THEN mntpat
|
|
END)
|
|
ELSE 0 END AS montant_net_a_payer_salarie,
|
|
t_rubriques.p_cumul,
|
|
t_rubriques.p_detail,
|
|
(max(ARRAY[extract(epoch from w_profils.date_debut), w_profils.contrat_mois_id]))[2] as contrat_mois_id,
|
|
(max(ARRAY[extract(epoch from w_profils.date_debut), w_profils.contrat_id]))[2] as contrat_id,
|
|
(max(ARRAY[extract(epoch from w_profils.date_debut), w_profils.profil_id]))[2] as profil_id
|
|
FROM temp.x_hst_paie
|
|
join w_profils on 1=1
|
|
and w_profils.sal_code_original = x_hst_paie.sal_code_original
|
|
and w_profils.cnt_code_original = x_hst_paie.cnt_code_original
|
|
and x_hst_paie.date_fin between w_profils.date_debut and w_profils.date_fin
|
|
JOIN rh.t_rubriques ON 1=1
|
|
and t_rubriques.code_original = x_hst_paie.rub_code_original
|
|
LEFT JOIN rh.t_compte ON 1=1
|
|
and t_compte.code_original = x_hst_paie.cpt_code_original
|
|
where false
|
|
OR t_rubriques.p_detail
|
|
OR t_rubriques.p_cumul
|
|
group by 1,2,3,4,5,6,7,8,9,10,11,12,13,14,15,16,17,18,19,20,21,22,23,24,25,26,27,28,29,30,31,32, x_hst_paie.ctid -- ce dernier regroupement nous assure de ne pas aggréger à tort des colonnes.
|
|
;
|
|
|
|
-- Génération paie
|
|
SELECT base.cti_stash_table_indexes('rh', 'p_historique_paie')
|
|
;
|
|
|
|
TRUNCATE rh.p_historique_paie
|
|
;
|
|
|
|
INSERT INTO rh.p_historique_paie(
|
|
code_original,
|
|
etablissement_id,
|
|
age_id,
|
|
contrat_id,
|
|
contrat_mois_id,
|
|
date_debut,
|
|
date_fin,
|
|
mois_activite,
|
|
date_paie,
|
|
mois_paie,
|
|
base,
|
|
nombre,
|
|
heure_contrat,
|
|
heure_payee,
|
|
heure_travaillee,
|
|
montant_masse_salariale,
|
|
montant_brut,
|
|
montant_avantage_nature,
|
|
montant_frais_imposables,
|
|
montant_cotisation_salarie,
|
|
montant_cotisation_patronale,
|
|
montant_od_net_salarie,
|
|
montant_od_net_patronale,
|
|
montant_net_imposable_salarie,
|
|
montant_net_a_payer_salarie,
|
|
taux_cotisation_salarie,
|
|
taux_cotisation_patronale,
|
|
organisme_cotisation_id,
|
|
profil_id,
|
|
rubrique_id,
|
|
compte_id,
|
|
salarie_id)
|
|
SELECT
|
|
w_hp.bul_id,
|
|
w_hp.etablissement_id,
|
|
date_part('year', age(w_hp.date_fin, p_salaries.date_naissance)) AS age_id,
|
|
w_hp.contrat_id,
|
|
w_hp.contrat_mois_id,
|
|
w_hp.date_debut,
|
|
w_hp.date_fin,
|
|
w_hp.mois_activite,
|
|
w_hp.date_paie,
|
|
w_hp.mois_paie,
|
|
w_hp.base,
|
|
w_hp.nombre,
|
|
w_hp.heure_contrat,
|
|
w_hp.heure_payee,
|
|
w_hp.heure_travaillee,
|
|
w_hp.montant_masse_salariale,
|
|
w_hp.montant_brut,
|
|
w_hp.montant_avantage_nature,
|
|
w_hp.montant_frais_imposables,
|
|
w_hp.montant_cotisation_salarie,
|
|
w_hp.montant_cotisation_patronale,
|
|
w_hp.montant_od_net_salarie,
|
|
w_hp.montant_od_net_patronale,
|
|
w_hp.montant_net_imposable_salarie,
|
|
w_hp.montant_net_a_payer_salarie,
|
|
w_hp.taux_cotisation_salarie,
|
|
w_hp.taux_cotisation_patronale,
|
|
w_hp.organisme_cotisation_id,
|
|
w_hp.profil_id,
|
|
w_hp.rubrique_id,
|
|
w_hp.compte_id,
|
|
w_hp.salarie_id
|
|
FROM w_hp
|
|
JOIN rh.p_salaries ON p_salaries.code_original = w_hp.sal_code_original
|
|
where p_detail
|
|
;
|
|
|
|
SELECT base.cti_stash_pop_table_indexes('rh', 'p_historique_paie')
|
|
;
|
|
|
|
-- Création d'une table récapitulative des écarts à calculer par indicateur de paie (1 seule ligne).
|
|
DROP TABLE IF EXISTS w_cumul
|
|
;
|
|
|
|
CREATE TEMP TABLE w_cumul AS
|
|
SELECT
|
|
bool_or(p_cumul and p_heures_contrat) as total_heures_contrat,
|
|
bool_or(p_cumul and p_heures_payees) as total_heures_payees,
|
|
bool_or(p_cumul and p_heures_travaillees) as total_heures_travaillees,
|
|
bool_or(p_cumul and p_masse_salariale) as total_masse_salariale,
|
|
bool_or(p_cumul and p_brut) as total_brut,
|
|
bool_or(p_cumul and p_avantage_nature) as total_avantage_nature,
|
|
bool_or(p_cumul and p_frais_imposables) as total_frais_imposables,
|
|
bool_or(p_cumul and p_cotisation_salarie) as total_cotisation_salarie,
|
|
bool_or(p_cumul and p_cotisation_patronale) as total_cotisation_patronale,
|
|
bool_or(p_cumul and p_od_net_salarie) as total_od_net_salarie,
|
|
bool_or(p_cumul and p_od_net_patronale) as total_od_net_patronale,
|
|
bool_or(p_cumul and p_net_imposable) as total_net_imposable,
|
|
bool_or(p_cumul and p_net_a_payer) as total_net_a_payer
|
|
FROM rh.t_rubriques
|
|
;
|
|
|
|
-- Création d'une table temp qui regroupe tous les totaux à atteindre pour calculer l'écart
|
|
DROP TABLE IF EXISTS w_totaux
|
|
;
|
|
|
|
CREATE TEMP TABLE w_totaux AS
|
|
SELECT
|
|
w_hp.bul_id,
|
|
w_hp.etablissement_id,
|
|
w_hp.salarie_id,
|
|
w_hp.mois_paie,
|
|
sum(case when p_heures_contrat then heure_contrat else 0 end) as heure_contrat,
|
|
sum(case when p_heures_payees then heure_payee else 0 end) as heure_payee,
|
|
sum(case when p_heures_travaillees then heure_travaillee else 0 end) as heure_travaillee,
|
|
sum(case when p_masse_salariale then montant_masse_salariale else 0 end) as montant_masse_salariale,
|
|
sum(case when p_brut then montant_brut else 0 end) AS montant_brut,
|
|
sum(case when p_avantage_nature then montant_avantage_nature else 0 end) as montant_avantage_nature,
|
|
sum(case when p_frais_imposables then montant_frais_imposables else 0 end) as montant_frais_imposables,
|
|
sum(case when p_cotisation_salarie then montant_cotisation_salarie else 0 end) AS montant_cotisation_salarie,
|
|
sum(case when p_cotisation_patronale then montant_cotisation_patronale else 0 end) AS montant_cotisation_patronale,
|
|
sum(case when p_od_net_salarie then montant_od_net_salarie else 0 end) as montant_od_net_salarie,
|
|
sum(case when p_od_net_patronale then montant_od_net_patronale else 0 end) as montant_od_net_patronale,
|
|
sum(case when p_net_imposable then montant_net_imposable_salarie else 0 end) as montant_net_imposable_salarie,
|
|
sum(case when p_net_a_payer then montant_net_a_payer_salarie else 0 end) as montant_net_a_payer_salarie
|
|
FROM w_hp
|
|
JOIN rh.t_rubriques ON t_rubriques.oid = w_hp.rubrique_id
|
|
where w_hp.p_cumul
|
|
GROUP BY 1,2,3,4
|
|
;
|
|
|
|
-- Insérer pour chaque bulletin une ligne qui va faire le compte avec le total (rubrique 'C000' nommée 'Ecart cumulé')
|
|
INSERT INTO rh.p_historique_paie (
|
|
code_original,
|
|
etablissement_id,
|
|
age_id,
|
|
contrat_id,
|
|
contrat_mois_id,
|
|
date_debut,
|
|
date_fin,
|
|
date_paie,
|
|
mois_activite,
|
|
mois_paie,
|
|
base,
|
|
nombre,
|
|
heure_contrat,
|
|
heure_payee,
|
|
heure_travaillee,
|
|
montant_masse_salariale,
|
|
montant_brut,
|
|
montant_avantage_nature,
|
|
montant_frais_imposables,
|
|
montant_cotisation_salarie,
|
|
montant_cotisation_patronale,
|
|
montant_od_net_salarie,
|
|
montant_od_net_patronale,
|
|
montant_net_imposable_salarie,
|
|
montant_net_a_payer_salarie,
|
|
organisme_cotisation_id,
|
|
profil_id, -- @deprecated
|
|
rubrique_id,
|
|
compte_id,
|
|
salarie_id,
|
|
taux_cotisation_patronale,
|
|
taux_cotisation_salarie)
|
|
WITH subq as (
|
|
SELECT
|
|
p_historique_paie.code_original as bul_id,
|
|
p_historique_paie.etablissement_id,
|
|
p_historique_paie.age_id,
|
|
p_historique_paie.contrat_id,
|
|
p_historique_paie.contrat_mois_id,
|
|
p_historique_paie.date_debut,
|
|
p_historique_paie.date_fin,
|
|
p_historique_paie.date_paie,
|
|
p_historique_paie.mois_activite,
|
|
p_historique_paie.mois_paie,
|
|
0 AS base,
|
|
0 AS nombre,
|
|
0 AS organisme_cotisation_id,
|
|
0 AS profil_id,
|
|
(SELECT oid FROM rh.t_rubriques WHERE code = 'C000') as rubrique_id,
|
|
0 as compte_id,
|
|
salarie_id,
|
|
0 AS taux_cotisation_patronale,
|
|
0 AS taux_cotisation_salarie,
|
|
sum(heure_contrat) AS heure_contrat,
|
|
sum(heure_payee) AS heure_payee,
|
|
sum(heure_travaillee) AS heure_travaillee,
|
|
sum(montant_masse_salariale) AS montant_masse_salariale,
|
|
sum(montant_brut) AS montant_brut,
|
|
sum(montant_avantage_nature) AS montant_avantage_nature,
|
|
sum(montant_frais_imposables) AS montant_frais_imposables,
|
|
sum(montant_cotisation_salarie) AS montant_cotisation_salarie,
|
|
sum(montant_cotisation_patronale) AS montant_cotisation_patronale,
|
|
sum(montant_od_net_salarie) AS montant_od_net_salarie,
|
|
sum(montant_od_net_patronale) AS montant_od_net_patronale,
|
|
sum(montant_net_imposable_salarie) AS montant_net_imposable_salarie,
|
|
sum(montant_net_a_payer_salarie) AS montant_net_a_payer_salarie
|
|
FROM rh.p_historique_paie
|
|
GROUP BY 1,2,3,4,5,6,7,8,9,10,11,12,13,14,15,16,17,18
|
|
)
|
|
SELECT
|
|
subq.bul_id,
|
|
subq.etablissement_id,
|
|
subq.age_id,
|
|
subq.contrat_id,
|
|
subq.contrat_mois_id,
|
|
subq.date_debut,
|
|
subq.date_fin,
|
|
subq.date_paie,
|
|
subq.mois_activite,
|
|
subq.mois_paie,
|
|
subq.base,
|
|
subq.nombre,
|
|
case when total_heures_contrat then w_totaux.heure_contrat - subq.heure_contrat else 0 end as heure_contrat,
|
|
case when total_heures_payees then w_totaux.heure_payee - subq.heure_payee else 0 end as heure_payee,
|
|
case when total_heures_travaillees then w_totaux.heure_travaillee - subq.heure_travaillee else 0 end as heure_travaillee,
|
|
case when total_masse_salariale then w_totaux.montant_masse_salariale - subq.montant_masse_salariale else 0 end as montant_masse_salariale,
|
|
case when total_brut then w_totaux.montant_brut - subq.montant_brut else 0 end as montant_brut,
|
|
case when total_avantage_nature then w_totaux.montant_avantage_nature - subq.montant_avantage_nature else 0 end as montant_avantage_nature,
|
|
case when total_frais_imposables then w_totaux.montant_frais_imposables - subq.montant_frais_imposables else 0 end as montant_frais_imposables,
|
|
case when total_cotisation_salarie then w_totaux.montant_cotisation_salarie - subq.montant_cotisation_salarie else 0 end as montant_cotisation_salarie,
|
|
case when total_cotisation_patronale then w_totaux.montant_cotisation_patronale - subq.montant_cotisation_patronale else 0 end as montant_cotisation_patronale,
|
|
case when total_od_net_salarie then w_totaux.montant_od_net_salarie - subq.montant_od_net_salarie else 0 end as montant_od_net_salarie,
|
|
case when total_od_net_patronale then w_totaux.montant_od_net_patronale - subq.montant_od_net_patronale else 0 end as montant_od_net_patronale,
|
|
case when total_net_imposable then w_totaux.montant_net_imposable_salarie - subq.montant_net_imposable_salarie else 0 end as montant_net_imposable_salarie,
|
|
case when total_net_a_payer then w_totaux.montant_net_a_payer_salarie - subq.montant_net_a_payer_salarie else 0 end as montant_net_a_payer_salarie,
|
|
subq.organisme_cotisation_id AS organisme_cotisation_id,
|
|
subq.profil_id,
|
|
subq.rubrique_id,
|
|
subq.compte_id,
|
|
subq.salarie_id,
|
|
subq.taux_cotisation_patronale,
|
|
subq.taux_cotisation_salarie
|
|
FROM subq
|
|
JOIN w_totaux ON w_totaux.bul_id = subq.bul_id
|
|
JOIN w_cumul ON true
|
|
WHERE 1!=1
|
|
OR (total_heures_contrat AND w_totaux.heure_contrat - subq.heure_contrat != 0)
|
|
OR (total_heures_payees AND w_totaux.heure_payee - subq.heure_payee != 0)
|
|
OR (total_heures_travaillees AND w_totaux.heure_travaillee - subq.heure_travaillee != 0)
|
|
OR (total_masse_salariale AND w_totaux.montant_masse_salariale - subq.montant_masse_salariale != 0)
|
|
OR (total_brut AND w_totaux.montant_brut - subq.montant_brut != 0)
|
|
OR (total_avantage_nature AND w_totaux.montant_avantage_nature - subq.montant_avantage_nature != 0)
|
|
OR (total_frais_imposables AND w_totaux.montant_frais_imposables - subq.montant_frais_imposables != 0)
|
|
OR (total_cotisation_salarie AND w_totaux.montant_cotisation_salarie - subq.montant_cotisation_salarie != 0)
|
|
OR (total_cotisation_patronale AND w_totaux.montant_cotisation_patronale - subq.montant_cotisation_patronale != 0)
|
|
OR (total_od_net_salarie AND w_totaux.montant_od_net_salarie - subq.montant_od_net_salarie != 0)
|
|
OR (total_od_net_patronale AND w_totaux.montant_od_net_patronale - subq.montant_od_net_patronale != 0)
|
|
OR (total_net_imposable AND w_totaux.montant_net_imposable_salarie - subq.montant_net_imposable_salarie != 0)
|
|
OR (total_net_a_payer AND w_totaux.montant_net_a_payer_salarie - subq.montant_net_a_payer_salarie != 0)
|
|
;
|
|
|
|
]]></sqlcmd>
|
|
</NODE>
|
|
<NODE label="Chiffrier">
|
|
<sqlcmd><![CDATA[
|
|
|
|
TRUNCATE rh.p_chiffrier_production
|
|
;
|
|
|
|
INSERT INTO rh.p_chiffrier_production (entreprise_id, etablissement_id, mois, nombre_salaries, montant_brut, nombre_heures)
|
|
SELECT
|
|
t_etablissements.entreprise_id,
|
|
w_totaux.etablissement_id,
|
|
w_totaux.mois_paie,
|
|
count(distinct salarie_id) as nombre_salaries,
|
|
sum(montant_brut) as montant_brut,
|
|
sum(heure_payee) as nombre_heures
|
|
from w_totaux
|
|
join rh.t_etablissements on t_etablissements.oid = w_totaux.etablissement_id
|
|
group by 1,2,3
|
|
;
|
|
|
|
]]></sqlcmd>
|
|
</NODE>
|
|
<NODE label="Ventilation des profils">
|
|
<sqlcmd><![CDATA[
|
|
|
|
-- Alimentation des profils simultanés.
|
|
TRUNCATE rh.p_profil_contrat_mois
|
|
;
|
|
|
|
INSERT INTO rh.p_profil_contrat_mois (
|
|
profil_id,
|
|
contrat_mois_id,
|
|
salarie_id,
|
|
ratio,
|
|
mois)
|
|
SELECT
|
|
w_profils.profil_id,
|
|
w_profils.contrat_mois_id,
|
|
w_profils.salarie_id,
|
|
1 AS ratio,
|
|
w_profils.mois
|
|
FROM w_profils
|
|
;
|
|
|
|
]]></sqlcmd>
|
|
</NODE>
|
|
<NODE name="VENTILATION" label="Ventilation analytique">
|
|
<condition><![CDATA[
|
|
|
|
SELECT valeur > 0
|
|
FROM rh.t_divers
|
|
WHERE code = 'PAIE_VENTILATION'
|
|
;
|
|
|
|
]]></condition>
|
|
<sqlcmd><![CDATA[
|
|
|
|
-- Insertion du Plan Analytique.
|
|
TRUNCATE rh.t_plan_analytique
|
|
;
|
|
INSERT INTO rh.t_plan_analytique(oid, code, texte)
|
|
VALUES ((SELECT valeur::bigint FROM rh.t_divers WHERE code = 'PAIE_VENTILATION'), 'VENTANA', 'Ventilation analytique')
|
|
;
|
|
|
|
-- Màj des sections analytiques.
|
|
DELETE FROM rh.t_section_analytique
|
|
WHERE oid != 0 -- Ne pas supprimer la section analytique N/R
|
|
;
|
|
|
|
INSERT INTO rh.t_section_analytique(oid, code_original, code, texte, texte_court)
|
|
select
|
|
oid,
|
|
code_original,
|
|
code,
|
|
texte,
|
|
coalesce(texte_court, substr(texte, 1, 50))
|
|
from temp.x_ref_section_analytique
|
|
where oid not in (select oid from rh.t_section_analytique group by 1)
|
|
;
|
|
|
|
DROP TABLE IF EXISTS w_ven_agg
|
|
;
|
|
|
|
CREATE TEMP TABLE w_ven_agg AS
|
|
select
|
|
bul_id,
|
|
dense_rank() over (order by array_agg(section_analytique_id order by section_analytique_id), array_agg(ratio order by section_analytique_id)) as ventilation_id,
|
|
array_to_string(array_agg(section_analytique_code_original||'@'||(round(ratio*100)) order by section_analytique_code_original), ', ') as ventilation_texte
|
|
FROM temp.x_ventilation
|
|
group by 1
|
|
;
|
|
|
|
-- Récupération des différents schémas/modèles de ventilation.
|
|
TRUNCATE rh.p_ventilation
|
|
;
|
|
|
|
INSERT INTO rh.p_ventilation(oid, code, texte, plan_analytique_id)
|
|
select
|
|
ventilation_id,
|
|
ventilation_id::text,
|
|
ventilation_texte,
|
|
(SELECT valeur::bigint FROM rh.t_divers WHERE code = 'PAIE_VENTILATION')
|
|
FROM w_ven_agg
|
|
group by 1,2,3,4
|
|
UNION ALL
|
|
SELECT
|
|
0,
|
|
'N/R',
|
|
'Non renseignée',
|
|
(SELECT valeur::bigint FROM rh.t_divers WHERE code = 'PAIE_VENTILATION')
|
|
;
|
|
|
|
TRUNCATE rh.p_ventilation_section
|
|
;
|
|
|
|
INSERT INTO rh.p_ventilation_section(
|
|
ventilation_id,
|
|
section_analytique_id,
|
|
section_analytique_code,
|
|
section_analytique_texte,
|
|
ratio)
|
|
SELECT
|
|
ventilation_id,
|
|
t_section_analytique.oid,
|
|
t_section_analytique.code,
|
|
t_section_analytique.texte,
|
|
ratio
|
|
from temp.x_ventilation
|
|
join w_ven_agg on w_ven_agg.bul_id = x_ventilation.bul_id
|
|
JOIN rh.t_section_analytique on t_section_analytique.oid = x_ventilation.section_analytique_id
|
|
group by 1,2,3,4,5
|
|
UNION ALL
|
|
SELECT
|
|
0,
|
|
oid,
|
|
code,
|
|
texte,
|
|
1
|
|
FROM rh.t_section_analytique
|
|
WHERE oid = 0
|
|
;
|
|
|
|
-- Application sur le plan 1.
|
|
UPDATE rh.p_historique_paie
|
|
SET ventilation_1_id = subq.ventilation_id
|
|
FROM (
|
|
select
|
|
p_historique_paie.oid,
|
|
coalesce(ventilation_id, 0) as ventilation_id
|
|
from rh.p_historique_paie
|
|
left join w_ven_agg on w_ven_agg.bul_id = p_historique_paie.code_original
|
|
group by 1,2) as subq
|
|
WHERE p_historique_paie.oid = subq.oid
|
|
;
|
|
|
|
]]></sqlcmd>
|
|
</NODE>
|
|
</NODE>
|
|
<NODE name="DIVERS">
|
|
<NODE label="Mise à jour de la table Divers (sauf mois en cours)">
|
|
<sqlcmd><![CDATA[
|
|
|
|
-- Màj de la date de dernier import.
|
|
DELETE FROM rh.t_divers
|
|
WHERE code = 'DERNIER_IMPORT'
|
|
;
|
|
|
|
INSERT INTO rh.t_divers(
|
|
code,
|
|
texte,
|
|
valeur,
|
|
valeur_date,
|
|
description)
|
|
VALUES(
|
|
'DERNIER_IMPORT',
|
|
'Dernier import.',
|
|
to_char(current_date, 'YYYYMM'),
|
|
current_date,
|
|
'Dernier import.'
|
|
)
|
|
;
|
|
|
|
-- Initialisation mois en cours/mois clôturé (NOW/NOWCLOTURE) lorsque pas déjà renseigné lors de l'import.
|
|
SELECT rh.cti_now('NOW','')
|
|
;
|
|
SELECT rh.cti_now('NOWCLOTURE','')
|
|
;
|
|
|
|
]]></sqlcmd>
|
|
</NODE>
|
|
</NODE>
|
|
<NODE name="POST">
|
|
<NODE label="Mise à jour de l'historique de paie (ancienne -> nouvelle version)">
|
|
<condition><![CDATA[
|
|
|
|
-- Option utilisé lors des fusions de prestataire avec un mélange ancienne version/nouvelle version (ex: SHS / CEGI).
|
|
with divers as (
|
|
select valeur = 1 as opt_hp_up
|
|
from rh.t_divers
|
|
where code = 'OPT_HP_UP')
|
|
, data_hp as (
|
|
select count(*) > 0 as data_fusion
|
|
from rh.p_historique_paie
|
|
where p_historique_paie.oid >= 100000000000 -- uniquement la paie des anciens prestataires.
|
|
)
|
|
select opt_hp_up and data_fusion
|
|
from divers, data_hp
|
|
;
|
|
|
|
]]></condition>
|
|
<sqlcmd><![CDATA[
|
|
|
|
-- Màj basée sur la vue SQL rh.v_historique_paie_0 et pour l'ancien prestataire uniquement.
|
|
with update_hp as (
|
|
SELECT
|
|
p_historique_paie.ctid,
|
|
coalesce(p_historique_paie.base, 0) * CASE
|
|
WHEN (@t_rubriques.coefficient_base) = 1 THEN 1
|
|
ELSE p_contrats_mois.ratio_temps_travail
|
|
END * t_rubriques.coefficient_base as base,
|
|
CASE
|
|
WHEN (@t_rubriques.coefficient_base) = 1 THEN coalesce(p_historique_paie.nombre, 0) * t_rubriques.coefficient_nombre
|
|
ELSE p_historique_paie.base
|
|
END AS nombre,
|
|
p_historique_paie.montant_brut
|
|
+ p_historique_paie.montant_avantage_nature
|
|
+ p_historique_paie.montant_frais_imposables
|
|
+ p_historique_paie.montant_cotisation_patronale
|
|
+ p_historique_paie.montant_od_net_patronale as montant_masse_salariale,
|
|
CASE
|
|
WHEN t_rubriques.code_calcul::text = 10::text THEN
|
|
CASE
|
|
WHEN t_rubriques.unite::text = 0::text THEN 1::numeric
|
|
ELSE t_rubriques.coefficient
|
|
END * p_historique_paie.base
|
|
ELSE 0::numeric
|
|
END AS heures_contrat,
|
|
CASE
|
|
WHEN t_rubriques.code_calcul::text = 1::text THEN
|
|
CASE
|
|
WHEN t_rubriques.unite::text = 0::text THEN 1::numeric
|
|
ELSE t_rubriques.coefficient
|
|
END * p_historique_paie.base
|
|
ELSE 0::numeric
|
|
END as heures_payees,
|
|
CASE
|
|
WHEN t_divers.valeur = '0'::text THEN
|
|
CASE
|
|
WHEN t_rubriques.code_calcul::text = 1::text THEN
|
|
CASE
|
|
WHEN t_rubriques.unite::text = 0::text THEN 1::numeric
|
|
ELSE t_rubriques.coefficient
|
|
END * p_historique_paie.base
|
|
ELSE 0::numeric
|
|
END -
|
|
CASE
|
|
WHEN t_rubriques.code_calcul::text = 2::text THEN
|
|
CASE
|
|
WHEN t_rubriques.unite::text = 0::text THEN 1::numeric
|
|
ELSE t_rubriques.coefficient
|
|
END * p_historique_paie.base
|
|
ELSE 0::numeric
|
|
END
|
|
ELSE
|
|
CASE
|
|
WHEN t_rubriques.code_calcul::text = 2::text THEN
|
|
CASE
|
|
WHEN t_rubriques.unite::text = 0::text THEN 1::numeric
|
|
ELSE t_rubriques.coefficient
|
|
END * p_historique_paie.base
|
|
ELSE 0::numeric
|
|
END
|
|
END heures_travaillees
|
|
FROM rh.p_historique_paie
|
|
JOIN rh.t_divers ON t_divers.code = 'HEURES_W'::text
|
|
JOIN rh.p_contrats_mois ON p_contrats_mois.oid = p_historique_paie.contrat_mois_id
|
|
JOIN rh.t_rubriques ON t_rubriques.oid = p_historique_paie.rubrique_id)
|
|
UPDATE rh.p_historique_paie SET
|
|
base = update_hp.base,
|
|
nombre = update_hp.nombre,
|
|
montant_masse_salariale = update_hp.montant_masse_salariale,
|
|
heure_contrat = update_hp.heures_contrat,
|
|
heure_payee = update_hp.heures_payees,
|
|
heure_travaillee = update_hp.heures_travaillees
|
|
FROM update_hp
|
|
WHERE true
|
|
AND p_historique_paie.ctid = update_hp.ctid
|
|
AND p_historique_paie.oid >= 100000000000 -- uniquement la paie des anciens prestataires.
|
|
AND (false -- et uniquement pour les lignes où c'est nécessaire.
|
|
OR p_historique_paie.base IS DISTINCT FROM update_hp.base
|
|
OR p_historique_paie.nombre IS DISTINCT FROM update_hp.nombre
|
|
OR p_historique_paie.montant_masse_salariale IS DISTINCT FROM update_hp.montant_masse_salariale
|
|
OR p_historique_paie.heure_contrat IS DISTINCT FROM update_hp.heures_contrat
|
|
OR p_historique_paie.heure_payee IS DISTINCT FROM update_hp.heures_payees
|
|
OR p_historique_paie.heure_travaillee IS DISTINCT FROM update_hp.heures_travaillees)
|
|
;
|
|
|
|
-- Resolution d'un problème d'integrite
|
|
UPDATE rh.p_historique_paie SET
|
|
etablissement_id = p_contrats.etablissement_id,
|
|
contrat_mois_id = p_contrats_mois.oid
|
|
FROM rh.p_contrats_mois
|
|
JOIN rh.p_contrats ON p_contrats_mois.contrat_id = p_contrats.oid
|
|
WHERE contrat_mois_id IS NULL AND
|
|
p_historique_paie.salarie_id = p_contrats_mois.salarie_id AND
|
|
p_historique_paie.contrat_id = p_contrats_mois.contrat_id AND
|
|
p_historique_paie.mois_paie = p_contrats_mois.mois_activite
|
|
;
|
|
|
|
]]></sqlcmd>
|
|
</NODE>
|
|
<NODE label="Compléments salariés">
|
|
<sqlcmd><![CDATA[
|
|
|
|
-- Profils
|
|
SELECT rh.cti_reorganize_profils()
|
|
;
|
|
|
|
-- Fusion
|
|
UPDATE rh.p_salaries
|
|
SET salarie_fusionne_id = 0
|
|
WHERE salarie_fusionne_id <> 0
|
|
;
|
|
|
|
SELECT rh.cti_fusion_salaries();
|
|
|
|
-- Table des personnes
|
|
SELECT rh.cti_reorganize_personne();
|
|
|
|
-- Forcage date sortie etablissement selon motif fin de contrat
|
|
UPDATE rh.p_salaries
|
|
SET date_sortie_ets = p_contrats.date_fin
|
|
FROM rh.p_contrats
|
|
JOIN
|
|
(
|
|
SELECT
|
|
p_contrats.salarie_id,
|
|
MAX(p_contrats.date_fin),
|
|
(MAX(array[p_contrats.date_fin::text, p_contrats.oid::text]))[2]::bigint AS last_contrat_id
|
|
FROM rh.p_contrats
|
|
GROUP BY 1
|
|
HAVING MAX(p_contrats.date_fin) <= now()
|
|
) subview ON p_contrats.oid = last_contrat_id
|
|
JOIN rh.p_profils ON p_contrats.profil_id = p_profils.oid
|
|
WHERE p_salaries.oid = subview.salarie_id AND
|
|
p_salaries.date_sortie_ets = '20991231' AND
|
|
p_profils.motif_fin_id IN (
|
|
SELECT to_id
|
|
FROM rh.t_listes
|
|
JOIN rh.t_listes_contenu ON t_listes.oid = t_listes_contenu.liste_id
|
|
WHERE t_listes.code = 'CTI_MFCDEP'
|
|
)
|
|
;
|
|
|
|
-- Assignation du plus récent entreprise_id (là où non renseigné)
|
|
UPDATE rh.p_salaries
|
|
SET entreprise_id = subview.dernier_entreprise_id
|
|
FROM
|
|
(
|
|
SELECT
|
|
p_salaries.oid AS salarie_id,
|
|
(MAX(array[p_contrats.date_fin::text, t_etablissements.entreprise_id::text]))[2]::bigint AS dernier_entreprise_id
|
|
FROM rh.p_salaries
|
|
JOIN rh.p_contrats ON p_contrats.salarie_id = p_salaries.oid
|
|
JOIN rh.t_etablissements ON t_etablissements.oid = p_contrats.etablissement_id
|
|
GROUP BY 1
|
|
) AS subview
|
|
WHERE
|
|
(p_salaries.entreprise_id = 0 OR p_salaries.entreprise_id IS NULL)
|
|
AND p_salaries.oid = subview.salarie_id
|
|
;
|
|
|
|
]]></sqlcmd>
|
|
</NODE>
|
|
<NODE label="Compléments contrats">
|
|
<sqlcmd><![CDATA[
|
|
|
|
UPDATE rh.p_salaries
|
|
SET date_anciennete = date_entree_ets
|
|
WHERE date_anciennete > date_entree_ets;
|
|
;
|
|
|
|
-- Màj de l'ancienneté.
|
|
UPDATE rh.p_contrats
|
|
SET
|
|
anciennete_anterieure_jours = subq.anciennete_anterieure_jours,
|
|
anciennete_anterieure_calculee_mois = subq.anciennete_anterieure_calculee_mois
|
|
FROM (
|
|
select
|
|
numero_contrat,
|
|
coalesce(sum(date_fin - date_debut + 1) over w, 0) AS anciennete_anterieure_jours,
|
|
coalesce(sum(date_fin - date_debut + 1) over w / 30::numeric, 0) AS anciennete_anterieure_calculee_mois
|
|
from rh.p_contrats
|
|
window w as (partition by salarie_id order by date_debut rows between UNBOUNDED PRECEDING and 1 preceding)) AS subq
|
|
WHERE 1=1
|
|
AND p_contrats.numero_contrat = subq.numero_contrat
|
|
;
|
|
|
|
-- Màj de l'ancienneté reprise.
|
|
UPDATE rh.p_contrats
|
|
SET
|
|
anciennete_reprise_anterieure_jours = subq.anciennete_reprise_anterieure_jours,
|
|
anciennete_reprise_anterieure_calculee_mois = subq.anciennete_reprise_anterieure_jours / 30
|
|
FROM
|
|
(
|
|
SELECT
|
|
p_contrats.numero_contrat,
|
|
COALESCE((p_contrats.anciennete_anterieure_jours + (p_salaries.date_entree_ets - p_salaries.date_anciennete)), 0) AS anciennete_reprise_anterieure_jours
|
|
FROM rh.p_salaries
|
|
JOIN rh.p_contrats ON p_contrats.salarie_id = p_salaries.oid
|
|
) AS subq
|
|
WHERE p_contrats.numero_contrat = subq.numero_contrat
|
|
;
|
|
|
|
UPDATE rh.p_contrats_mois
|
|
SET
|
|
anciennete_jours = subq.anciennete_jours,
|
|
anciennete_reprise_jours = subq.anciennete_reprise_jours,
|
|
anciennete_mois = subq.anciennete_mois,
|
|
anciennete_reprise_mois = subq.anciennete_reprise_mois,
|
|
anciennete_annee_id = subq.anciennete_annee_id,
|
|
anciennete_reprise_annee_id = subq.anciennete_reprise_annee_id
|
|
FROM
|
|
(
|
|
SELECT
|
|
p_contrats.salarie_id,
|
|
p_contrats.oid AS contrat_id,
|
|
p_contrats_mois.oid AS contrat_mois_id,
|
|
p_contrats.anciennete_anterieure_jours
|
|
+ (p_contrats_mois.date_fin - p_contrats.date_debut)
|
|
+ 1 AS anciennete_jours,
|
|
p_contrats.anciennete_reprise_anterieure_jours
|
|
+ (p_contrats_mois.date_fin - p_contrats.date_debut) AS anciennete_reprise_jours,
|
|
base.cti_age(date_trunc('month', p_contrats_mois.date_fin)::date, date_trunc('month', p_contrats.date_debut)::date, 'nm')
|
|
+ GREATEST(p_contrats.anciennete_anterieure_mois, p_contrats.anciennete_anterieure_calculee_mois)
|
|
+ 1 AS anciennete_mois,
|
|
base.cti_age(date_trunc('month', p_contrats_mois.date_fin)::date, date_trunc('month', p_contrats.date_debut)::date, 'nm')
|
|
+ p_contrats.anciennete_reprise_anterieure_calculee_mois AS anciennete_reprise_mois,
|
|
floor((base.cti_age(date_trunc('month', p_contrats_mois.date_fin::date)::date, date_trunc('month', p_contrats.date_debut)::date, 'nm')
|
|
+ GREATEST(p_contrats.anciennete_anterieure_mois, p_contrats.anciennete_anterieure_calculee_mois)
|
|
+ 1) / 12) AS anciennete_annee_id,
|
|
floor((base.cti_age(date_trunc('month', p_contrats_mois.date_fin::date)::date, date_trunc('month', p_contrats.date_debut)::date, 'nm')
|
|
+ p_contrats.anciennete_reprise_anterieure_calculee_mois) / 12) AS anciennete_reprise_annee_id
|
|
FROM rh.p_contrats
|
|
JOIN rh.p_contrats_mois ON p_contrats_mois.contrat_id = p_contrats.oid
|
|
) AS subq
|
|
WHERE
|
|
p_contrats_mois.salarie_id = subq.salarie_id
|
|
AND p_contrats_mois.contrat_id = subq.contrat_id
|
|
AND p_contrats_mois.oid = subq.contrat_mois_id
|
|
;
|
|
|
|
-- Màj des compteurs
|
|
UPDATE rh.p_contrats_mois SET
|
|
nombre_entrees = CASE WHEN p_salaries.date_entree_ets BETWEEN p_contrats_mois.date_debut AND p_contrats_mois.date_fin THEN 1 ELSE 0 END,
|
|
nombre_departs = CASE WHEN p_salaries.date_sortie_ets BETWEEN p_contrats_mois.date_debut AND p_contrats_mois.date_fin THEN 1 ELSE 0 END,
|
|
nombre_debut_contrat = CASE WHEN p_contrats.date_debut BETWEEN p_contrats_mois.date_debut AND p_contrats_mois.date_fin THEN 1 ELSE 0 END,
|
|
nombre_fin_contrat = CASE WHEN p_contrats.date_fin BETWEEN p_contrats_mois.date_debut AND p_contrats_mois.date_fin THEN 1 ELSE 0 END,
|
|
present_debut_mois = CASE WHEN p_contrats_mois.date_debut = base.cti_first_day(p_contrats_mois.date_debut) THEN 1 ELSE 0 END,
|
|
present_fin_mois = CASE WHEN p_contrats_mois.date_fin = base.cti_last_day(p_contrats_mois.date_fin) THEN 1 ELSE 0 END,
|
|
age_jours = p_contrats_mois.date_fin - COALESCE(p_salaries.date_naissance, '1962-04-18'::date)
|
|
FROM rh.p_salaries, rh.p_contrats
|
|
WHERE 1=1
|
|
AND p_salaries.oid = p_contrats_mois.salarie_id
|
|
AND p_contrats.oid = p_contrats_mois.contrat_id
|
|
;
|
|
|
|
with flagged_cnt as (
|
|
select
|
|
p_contrats.oid,
|
|
coalesce(lag(p_contrats.date_fin) over w + '1 day'::interval = p_contrats.date_debut and
|
|
lag(p_profils.motif_fin_code) over w in (select unnest(string_to_array(replace(valeur, ' ', ''), ',')) from rh.t_divers where code = 'OPT_CNT_FIN_FUSION'), false) as pas_top_debut,
|
|
p_profils.motif_fin_code in (select unnest(string_to_array(replace(valeur, ' ', ''), ',')) from rh.t_divers where code = 'OPT_CNT_FIN_FUSION') as pas_top_fin
|
|
from rh.p_contrats
|
|
join rh.p_profils on p_profils.oid = p_contrats.profil_id
|
|
window w as (partition by p_contrats.salarie_id order by p_contrats.date_debut))
|
|
update rh.p_contrats_mois set
|
|
nombre_debut_contrat = case when pas_top_debut then '0' else nombre_debut_contrat end,
|
|
nombre_fin_contrat = case when pas_top_fin then '0' else nombre_fin_contrat end
|
|
from flagged_cnt
|
|
where true
|
|
and p_contrats_mois.contrat_id = flagged_cnt.oid
|
|
and (false
|
|
or pas_top_debut
|
|
or pas_top_fin)
|
|
;
|
|
|
|
with toto as (
|
|
select
|
|
p_contrats_mois.oid,
|
|
case when type_contrat_section_code[9] = 'CDI' and lag(type_contrat_section_code[9]) over w != 'CDI' then 1 else 0 end as nombre_transformation_cdi
|
|
from rh.p_contrats_mois
|
|
JOIN rh.p_profil_contrat_mois ON p_profil_contrat_mois.contrat_mois_id = p_contrats_mois.oid
|
|
join rh.p_profils on p_profils.oid = p_profil_contrat_mois.profil_id
|
|
window w as (partition by p_contrats_mois.salarie_id order by p_contrats_mois.date_debut))
|
|
UPDATE rh.p_contrats_mois SET
|
|
nombre_transformation_cdi = toto.nombre_transformation_cdi
|
|
FROM toto
|
|
WHERE 1=1
|
|
AND p_contrats_mois.oid = toto.oid
|
|
AND p_contrats_mois.nombre_transformation_cdi IS DISTINCT FROM toto.nombre_transformation_cdi
|
|
;
|
|
|
|
/* CONTRATS */
|
|
-- MAJ de l'age contrat si ce dernier est 0
|
|
WITH w_age_contrat AS
|
|
(
|
|
SELECT
|
|
p_contrats_mois.oid,
|
|
base.cti_age(p_contrats_mois.date_fin, coalesce(p_salaries.date_naissance, '1962-04-18'::date), 'ny') AS age_id
|
|
FROM rh.p_contrats_mois
|
|
JOIN rh.p_salaries ON p_contrats_mois.salarie_id = p_salaries.oid
|
|
)
|
|
UPDATE rh.p_contrats_mois
|
|
SET age_id = w_age_contrat.age_id
|
|
FROM w_age_contrat
|
|
WHERE p_contrats_mois.oid = w_age_contrat.oid
|
|
;
|
|
|
|
-- Màj des âges (plage autorisée : 0 -> 110 ans)
|
|
UPDATE rh.p_contrats_mois
|
|
SET age_id = 0
|
|
WHERE age_id < 0
|
|
;
|
|
|
|
UPDATE rh.p_contrats_mois
|
|
SET age_id = (SELECT max(oid) FROM rh.t_ages)
|
|
WHERE age_id > (SELECT max(oid) FROM rh.t_ages)
|
|
;
|
|
|
|
-- Màj des anciennetés (plage autorisée : 0 -> 50 ans)
|
|
UPDATE rh.p_contrats_mois
|
|
SET
|
|
anciennete_jours = 0,
|
|
anciennete_reprise_jours = 0,
|
|
anciennete_mois = 0,
|
|
anciennete_reprise_mois = 0,
|
|
anciennete_annee_id = 0,
|
|
anciennete_reprise_annee_id = 0
|
|
WHERE anciennete_jours <= 0
|
|
;
|
|
|
|
UPDATE rh.p_contrats_mois
|
|
SET anciennete_annee_id = (SELECT max(oid) FROM rh.t_anciennetes_annee)
|
|
WHERE anciennete_annee_id > (SELECT max(oid) FROM rh.t_anciennetes_annee)
|
|
;
|
|
|
|
UPDATE rh.p_contrats_mois
|
|
SET anciennete_reprise_annee_id = (SELECT max(oid) FROM rh.t_anciennetes_annee)
|
|
WHERE anciennete_reprise_annee_id > (SELECT max(oid) FROM rh.t_anciennetes_annee)
|
|
;
|
|
|
|
-- Màj des établissements dans p_contrats_mois lorsque non renseigné lors de l'import.
|
|
UPDATE rh.p_contrats_mois
|
|
SET etablissement_id = p_contrats.etablissement_id
|
|
FROM rh.p_contrats
|
|
WHERE 1=1
|
|
AND p_contrats_mois.contrat_id = p_contrats.oid
|
|
AND p_contrats_mois.etablissement_id IS NULL
|
|
;
|
|
|
|
]]></sqlcmd>
|
|
</NODE>
|
|
|
|
<NODE label="Optimisation des tables">
|
|
<sqlcmd><![CDATA[
|
|
|
|
ANALYZE rh.p_contrats
|
|
;
|
|
ANALYZE rh.p_contrats_mois
|
|
;
|
|
ANALYZE rh.p_historique_paie
|
|
;
|
|
|
|
]]></sqlcmd>
|
|
</NODE>
|
|
|
|
<NODE label="Nettoyage salariés et contrats">
|
|
<sqlcmd><![CDATA[
|
|
|
|
/* SALARIES */
|
|
-- Suppression des salariés n'ayant ni contrat ni paie.
|
|
DROP TABLE IF EXISTS w_sal_to_delete
|
|
;
|
|
|
|
CREATE TEMP TABLE w_sal_to_delete AS
|
|
SELECT p_salaries.oid
|
|
FROM rh.p_salaries
|
|
LEFT JOIN rh.p_contrats ON p_contrats.salarie_id = p_salaries.oid
|
|
LEFT JOIN rh.p_historique_paie ON p_historique_paie.salarie_id = p_salaries.oid
|
|
WHERE true
|
|
AND salarie_fusionne_id = 0
|
|
AND p_contrats.salarie_id IS NULL
|
|
AND p_historique_paie.salarie_id IS NULL
|
|
;
|
|
|
|
DELETE FROM rh.p_contrats_mois
|
|
WHERE salarie_id IN (select oid from w_sal_to_delete)
|
|
;
|
|
|
|
DELETE FROM rh.p_contrats
|
|
WHERE salarie_id IN (select oid from w_sal_to_delete)
|
|
;
|
|
|
|
DELETE FROM rh.p_salaries
|
|
WHERE oid IN (select oid from w_sal_to_delete)
|
|
;
|
|
|
|
]]></sqlcmd>
|
|
</NODE>
|
|
|
|
<NODE label="Âges et ancienneté">
|
|
<sqlcmd><![CDATA[
|
|
|
|
INSERT INTO rh.t_ages(oid, code, texte)
|
|
SELECT age_id, lpad(age_id, 3, '0'), age_id::text||' ans'
|
|
FROM rh.p_contrats_mois
|
|
LEFT JOIN rh.t_ages ON t_ages.oid = p_contrats_mois.age_id
|
|
WHERE t_ages.oid is null
|
|
GROUP BY age_id
|
|
;
|
|
|
|
INSERT INTO rh.t_anciennetes_annee(oid, code, texte)
|
|
SELECT anciennete_annee_id, lpad(anciennete_annee_id, 2, '0'), anciennete_annee_id::text||' ans'
|
|
FROM rh.p_contrats_mois
|
|
LEFT JOIN rh.t_anciennetes_annee ON t_anciennetes_annee.oid = p_contrats_mois.anciennete_annee_id
|
|
WHERE t_anciennetes_annee.oid is null
|
|
AND p_contrats_mois.anciennete_annee_id IS NOT NULL
|
|
GROUP BY anciennete_annee_id
|
|
;
|
|
|
|
]]></sqlcmd>
|
|
</NODE>
|
|
|
|
<NODE label="Historique paie">
|
|
<sqlcmd><![CDATA[
|
|
|
|
-- Màj de l'établissement pour chaque ligne de paie lorsque non renseigné.
|
|
UPDATE rh.p_historique_paie SET
|
|
etablissement_id = p_contrats_mois.etablissement_id
|
|
FROM rh.p_contrats_mois
|
|
WHERE 1=1
|
|
AND p_historique_paie.contrat_mois_id = p_contrats_mois.oid
|
|
AND p_historique_paie.etablissement_id IS NULL
|
|
;
|
|
|
|
-- Màj des heures contrats à 0 pour chaque ligne de paie lorsque NULL.
|
|
update rh.p_historique_paie
|
|
set heure_contrat = 0
|
|
where heure_contrat is null
|
|
;
|
|
|
|
-- Calcul du montant brut moyen par année et montant brut annuel pour tous les salariés
|
|
DROP TABLE IF EXISTS montants_brut_cumules
|
|
;
|
|
|
|
CREATE TEMP TABLE montants_brut_cumules AS
|
|
with montants_brut_mensuel AS (
|
|
SELECT
|
|
salarie_id,
|
|
substr(p_historique_paie.mois_activite::text, 1, 4) AS annee,
|
|
mois_paie,
|
|
SUM(montant_brut) AS montant_brut_mensuel
|
|
FROM rh.p_historique_paie
|
|
WHERE montant_brut <> 0
|
|
GROUP BY 1,2,3
|
|
)
|
|
SELECT
|
|
salarie_id,
|
|
annee,
|
|
MAX(mois_paie) AS mois_paie_max,
|
|
SUM(montant_brut_mensuel) AS montant_brut_annuel,
|
|
AVG(montant_brut_mensuel) AS montant_brut_mensuel_moyen
|
|
FROM montants_brut_mensuel
|
|
GROUP BY 1,2
|
|
ORDER BY 1,2
|
|
;
|
|
|
|
-- Mise à jour du montant_brut_mensuel_moyen et montant_brut_annuel sur la dernière ligne d'historique de paie du salarié
|
|
UPDATE rh.p_historique_paie
|
|
SET
|
|
montant_brut_annuel = subview.montant_brut_annuel,
|
|
montant_brut_mensuel_moyen = subview.montant_brut_mensuel_moyen
|
|
FROM
|
|
(
|
|
with max_oid AS
|
|
(
|
|
SELECT
|
|
montants_brut_cumules.salarie_id,
|
|
montants_brut_cumules.annee,
|
|
MAX(p_historique_paie.oid) AS oid_to_update
|
|
FROM rh.p_historique_paie
|
|
JOIN montants_brut_cumules ON montants_brut_cumules.salarie_id = p_historique_paie.salarie_id AND montants_brut_cumules.mois_paie_max = p_historique_paie.mois_paie
|
|
GROUP BY 1,2
|
|
)
|
|
SELECT
|
|
max_oid.oid_to_update,
|
|
montants_brut_cumules.salarie_id,
|
|
montants_brut_cumules.montant_brut_annuel,
|
|
montants_brut_cumules.montant_brut_mensuel_moyen
|
|
FROM montants_brut_cumules
|
|
JOIN max_oid ON max_oid.salarie_id = montants_brut_cumules.salarie_id AND max_oid.annee = montants_brut_cumules.annee
|
|
) AS subview
|
|
WHERE p_historique_paie.oid = subview.oid_to_update
|
|
;
|
|
|
|
]]></sqlcmd>
|
|
</NODE>
|
|
|
|
<NODE label="Profils">
|
|
<sqlcmd><![CDATA[
|
|
|
|
-- Màj des motifs de fin lorsque le contrat du salarié est toujours ouvert.
|
|
DROP TABLE IF EXISTS w_elected_contract
|
|
;
|
|
|
|
CREATE TEMP TABLE w_elected_contract AS
|
|
select
|
|
salarie_id,
|
|
p_contrats.oid as contrat_id
|
|
from rh.p_contrats
|
|
where date_fin = '2099-12-31'::date
|
|
;
|
|
|
|
DROP TABLE IF EXISTS w_elected_profil
|
|
;
|
|
|
|
CREATE TEMP TABLE w_elected_profil AS
|
|
select oid as elected_profil_id
|
|
from rh.p_profils
|
|
where 1=1
|
|
and motif_fin_id = 0 -- Cibler uniquement les profils ayant un motif de fin N/R et...
|
|
and oid != 0 -- ... qui n'est pas le profil N/R.
|
|
;
|
|
|
|
DROP TABLE IF EXISTS w_elected_profil_contract
|
|
;
|
|
|
|
CREATE TEMP TABLE w_elected_profil_contract AS
|
|
select
|
|
p_contrats.oid as contrat_id,
|
|
p_contrats.profil_id
|
|
from rh.p_contrats
|
|
join w_elected_contract on w_elected_contract.contrat_id = p_contrats.oid
|
|
join w_elected_profil on w_elected_profil.elected_profil_id = p_contrats.profil_id
|
|
;
|
|
|
|
DROP TABLE IF EXISTS w_elected_profil_salarie
|
|
;
|
|
|
|
CREATE TEMP TABLE w_elected_profil_salarie AS
|
|
select
|
|
p_salaries.oid as salarie_id,
|
|
p_salaries.profil_id
|
|
from rh.p_salaries
|
|
join w_elected_contract on w_elected_contract.salarie_id = p_salaries.oid
|
|
join w_elected_profil on w_elected_profil.elected_profil_id = p_salaries.profil_id
|
|
;
|
|
|
|
DROP TABLE IF EXISTS w_elected_profil_profil
|
|
;
|
|
|
|
CREATE TEMP TABLE w_elected_profil_profil AS
|
|
select
|
|
p_profil_contrat_mois.oid as profil_contrat_mois_id,
|
|
p_profil_contrat_mois.profil_id
|
|
from rh.p_profil_contrat_mois
|
|
join rh.p_contrats_mois on p_contrats_mois.oid = p_profil_contrat_mois.contrat_mois_id
|
|
join w_elected_contract on w_elected_contract.contrat_id = p_contrats_mois.contrat_id
|
|
join w_elected_profil on w_elected_profil.elected_profil_id = p_profil_contrat_mois.profil_id
|
|
;
|
|
|
|
-- Opération de maintenance utile uniquement dans l'étape de FUSION en sachant qu'idéalement IL NE FAUDRAIT PAS faire cette opération lors de cette étape.
|
|
select setval('rh.s_profils'::regclass, (select GREATEST(max(oid),1) from rh.p_profils))
|
|
;
|
|
|
|
DROP TABLE IF EXISTS w_old_new_profil
|
|
;
|
|
|
|
CREATE TEMP TABLE w_old_new_profil AS
|
|
with w_elected_profil as (
|
|
select profil_id
|
|
from w_elected_profil_contract
|
|
union
|
|
select profil_id
|
|
from w_elected_profil_salarie
|
|
union
|
|
select profil_id
|
|
from w_elected_profil_profil
|
|
)
|
|
SELECT
|
|
p_profils.oid as old_profil_id,
|
|
nextval('rh.s_profils'::regclass) as new_profil_id,
|
|
p_profils.cadre_emploi_code_original,
|
|
p_profils.categorie_conge_code_original,
|
|
p_profils.categorie_socio_professionnelle_code_original,
|
|
p_profils.categorie_statutaire_code_original,
|
|
p_profils.code_emploi_code_original,
|
|
p_profils.commission_paritaire_code_original,
|
|
p_profils.compte_salarie_code_original,
|
|
p_profils.filiere_code_original,
|
|
p_profils.grille_code_original,
|
|
p_profils.grille_groupe_code_original,
|
|
p_profils.groupe_cotisant_code_original,
|
|
p_profils.lettre_budgetaire_code_original,
|
|
p_profils.motif_debut_code_original,
|
|
'CTI_CNT_EC'::text as motif_fin_code_original,
|
|
p_profils.qualification_code_original,
|
|
p_profils.section_analytique_code_original,
|
|
p_profils.section_analytique_paie_code_original,
|
|
p_profils.service_code_original,
|
|
p_profils.societe_interim_code_original,
|
|
p_profils.specialite_code_original,
|
|
p_profils.statut_code_original,
|
|
p_profils.type_contrat_code_original,
|
|
p_profils.type_horaire_code_original,
|
|
p_profils.type_temps_travail_code_original,
|
|
p_profils.unite_fonctionnelle_code_original
|
|
FROM rh.p_profils
|
|
join w_elected_profil on w_elected_profil.profil_id = p_profils.oid
|
|
GROUP BY 1,2,3,4,5,6,7,8,9,10,11,12,13,14,15,16,17,18,19,20,21,22,23,24,25,26,27
|
|
;
|
|
|
|
INSERT INTO rh.p_profils (
|
|
oid,
|
|
cadre_emploi_code_original,
|
|
categorie_conge_code_original,
|
|
categorie_socio_professionnelle_code_original,
|
|
categorie_statutaire_code_original,
|
|
code_emploi_code_original,
|
|
commission_paritaire_code_original,
|
|
compte_salarie_code_original,
|
|
filiere_code_original,
|
|
grille_code_original,
|
|
grille_groupe_code_original,
|
|
groupe_cotisant_code_original,
|
|
lettre_budgetaire_code_original,
|
|
motif_debut_code_original,
|
|
motif_fin_code_original,
|
|
qualification_code_original,
|
|
section_analytique_code_original,
|
|
section_analytique_paie_code_original,
|
|
service_code_original,
|
|
societe_interim_code_original,
|
|
specialite_code_original,
|
|
statut_code_original,
|
|
type_contrat_code_original,
|
|
type_horaire_code_original,
|
|
type_temps_travail_code_original,
|
|
unite_fonctionnelle_code_original)
|
|
SELECT
|
|
w_old_new_profil.new_profil_id,
|
|
w_old_new_profil.cadre_emploi_code_original,
|
|
w_old_new_profil.categorie_conge_code_original,
|
|
w_old_new_profil.categorie_socio_professionnelle_code_original,
|
|
w_old_new_profil.categorie_statutaire_code_original,
|
|
w_old_new_profil.code_emploi_code_original,
|
|
w_old_new_profil.commission_paritaire_code_original,
|
|
w_old_new_profil.compte_salarie_code_original,
|
|
w_old_new_profil.filiere_code_original,
|
|
w_old_new_profil.grille_code_original,
|
|
w_old_new_profil.grille_groupe_code_original,
|
|
w_old_new_profil.groupe_cotisant_code_original,
|
|
w_old_new_profil.lettre_budgetaire_code_original,
|
|
w_old_new_profil.motif_debut_code_original,
|
|
w_old_new_profil.motif_fin_code_original,
|
|
w_old_new_profil.qualification_code_original,
|
|
w_old_new_profil.section_analytique_code_original,
|
|
w_old_new_profil.section_analytique_paie_code_original,
|
|
w_old_new_profil.service_code_original,
|
|
w_old_new_profil.societe_interim_code_original,
|
|
w_old_new_profil.specialite_code_original,
|
|
w_old_new_profil.statut_code_original,
|
|
w_old_new_profil.type_contrat_code_original,
|
|
w_old_new_profil.type_horaire_code_original,
|
|
w_old_new_profil.type_temps_travail_code_original,
|
|
w_old_new_profil.unite_fonctionnelle_code_original
|
|
FROM w_old_new_profil
|
|
GROUP BY 1,2,3,4,5,6,7,8,9,10,11,12,13,14,15,16,17,18,19,20,21,22,23,24,25,26
|
|
;
|
|
|
|
SELECT rh.cti_reorganize_profils()
|
|
;
|
|
|
|
with to_upd as (
|
|
select
|
|
w_elected_profil_contract.contrat_id,
|
|
w_old_new_profil.new_profil_id
|
|
from w_elected_profil_contract
|
|
join w_old_new_profil on w_old_new_profil.old_profil_id = w_elected_profil_contract.profil_id
|
|
)
|
|
update rh.p_contrats set
|
|
profil_id = to_upd.new_profil_id
|
|
from to_upd
|
|
where 1=1
|
|
and p_contrats.oid = to_upd.contrat_id
|
|
and p_contrats.profil_id is distinct from to_upd.new_profil_id
|
|
;
|
|
|
|
with to_upd as (
|
|
select
|
|
w_elected_profil_salarie.salarie_id,
|
|
w_old_new_profil.new_profil_id
|
|
from w_elected_profil_salarie
|
|
join w_old_new_profil on w_old_new_profil.old_profil_id = w_elected_profil_salarie.profil_id
|
|
)
|
|
update rh.p_salaries set
|
|
profil_id = to_upd.new_profil_id
|
|
from to_upd
|
|
where 1=1
|
|
and p_salaries.oid = to_upd.salarie_id
|
|
and p_salaries.profil_id is distinct from to_upd.new_profil_id
|
|
;
|
|
|
|
with to_upd as (
|
|
select
|
|
w_elected_profil_profil.profil_contrat_mois_id,
|
|
w_old_new_profil.new_profil_id
|
|
from w_elected_profil_profil
|
|
join w_old_new_profil on w_old_new_profil.old_profil_id = w_elected_profil_profil.profil_id
|
|
)
|
|
update rh.p_profil_contrat_mois set
|
|
profil_id = to_upd.new_profil_id
|
|
from to_upd
|
|
where 1=1
|
|
and p_profil_contrat_mois.oid = to_upd.profil_contrat_mois_id
|
|
and p_profil_contrat_mois.profil_id is distinct from to_upd.new_profil_id
|
|
;
|
|
|
|
-- Opération de maintenance utile uniquement dans l'étape de FUSION en sachant qu'idéalement IL NE FAUDRAIT PAS faire cette opération lors de cette étape.
|
|
select setval('rh.s_profils'::regclass, (select GREATEST(max(oid),1) from rh.p_profils))
|
|
;
|
|
|
|
]]></sqlcmd>
|
|
</NODE>
|
|
|
|
<NODE label="Profils (fonctions CTI)">
|
|
<sqlcmd><![CDATA[
|
|
|
|
/* PROFILS */
|
|
-- Réorganisation/Màj de la table p_profils
|
|
SELECT base.cti_stash_table_constraints('rh.p_profils')
|
|
;
|
|
|
|
SELECT base.cti_stash_table_indexes('rh.p_profils')
|
|
;
|
|
|
|
SELECT rh.cti_reorganize_profils()
|
|
;
|
|
|
|
SELECT base.cti_stash_pop_table_constraints('rh.p_profils')
|
|
;
|
|
|
|
SELECT base.cti_stash_pop_table_indexes('rh.p_profils')
|
|
;
|
|
|
|
]]></sqlcmd>
|
|
</NODE>
|
|
|
|
<NODE label="Clés budgétaires (fonctions CTI)">
|
|
<sqlcmd><![CDATA[
|
|
|
|
/* Clés budgétaires */
|
|
SELECT rh.cti_budget_execute_rules()
|
|
;
|
|
|
|
]]></sqlcmd>
|
|
</NODE>
|
|
|
|
<NODE label="OIDS (fonctions CTI)">
|
|
<sqlcmd><![CDATA[
|
|
|
|
/* OIDS */
|
|
-- Màj de la table p_oids
|
|
TRUNCATE rh.p_oids
|
|
;
|
|
|
|
SELECT base.cti_stash_table_constraints('rh', 'p_oids')
|
|
;
|
|
|
|
SELECT base.cti_stash_table_indexes('rh', 'p_oids')
|
|
;
|
|
|
|
INSERT INTO rh.p_oids (code_table, oid)
|
|
SELECT 'ages', age_id
|
|
FROM rh.p_contrats_mois
|
|
GROUP BY 1,2
|
|
;
|
|
|
|
INSERT INTO rh.p_oids (code_table, oid)
|
|
SELECT 'anciennetes_annee', anciennete_annee_id
|
|
FROM rh.p_contrats_mois
|
|
GROUP BY 1,2
|
|
;
|
|
|
|
INSERT INTO rh.p_oids (code_table, oid)
|
|
SELECT 'salaries', salarie_id
|
|
FROM rh.p_contrats_mois
|
|
GROUP BY 1,2
|
|
;
|
|
|
|
INSERT INTO rh.p_oids (code_table, oid)
|
|
SELECT 'services', service_id
|
|
FROM rh.p_profils
|
|
GROUP BY 1,2
|
|
;
|
|
|
|
INSERT INTO rh.p_oids (code_table, oid)
|
|
SELECT 'qualifications', qualification_id
|
|
FROM rh.p_profils
|
|
GROUP BY 1,2
|
|
;
|
|
|
|
INSERT INTO rh.p_oids (code_table, oid)
|
|
SELECT 'types_temps_travail', type_temps_travail_id
|
|
FROM rh.p_profils
|
|
GROUP BY 1,2
|
|
;
|
|
|
|
INSERT INTO rh.p_oids (code_table, oid)
|
|
SELECT 'types_contrat', type_contrat_id
|
|
FROM rh.p_profils
|
|
GROUP BY 1,2
|
|
;
|
|
|
|
INSERT INTO rh.p_oids (code_table, oid)
|
|
SELECT 'specialites', specialite_id
|
|
FROM rh.p_profils
|
|
GROUP BY 1,2
|
|
;
|
|
|
|
INSERT INTO rh.p_oids (code_table, oid)
|
|
SELECT 'categories_socio_professionnelle', categorie_socio_professionnelle_id
|
|
FROM rh.p_profils
|
|
GROUP BY 1,2
|
|
;
|
|
|
|
INSERT INTO rh.p_oids (code_table, oid)
|
|
SELECT 'statuts', statut_id
|
|
FROM rh.p_profils
|
|
GROUP BY 1,2
|
|
;
|
|
|
|
INSERT INTO rh.p_oids (code_table, oid)
|
|
SELECT 'codes_emploi', code_emploi_id
|
|
FROM rh.p_profils
|
|
GROUP BY 1,2
|
|
;
|
|
|
|
INSERT INTO rh.p_oids (code_table, oid)
|
|
SELECT 'motifs_debut_contrat', motif_debut_id
|
|
FROM rh.p_profils
|
|
GROUP BY 1,2
|
|
;
|
|
|
|
INSERT INTO rh.p_oids (code_table, oid)
|
|
SELECT 'motifs_fin_contrat', motif_fin_id
|
|
FROM rh.p_profils
|
|
GROUP BY 1,2
|
|
;
|
|
|
|
INSERT INTO rh.p_oids (code_table, oid)
|
|
SELECT 'situations_famille', situation_famille_id
|
|
FROM rh.p_salaries
|
|
GROUP BY 1,2
|
|
;
|
|
|
|
INSERT INTO rh.p_oids (code_table, oid)
|
|
SELECT 'nationalites', nationalite_id
|
|
FROM rh.p_salaries
|
|
GROUP BY 1,2
|
|
;
|
|
|
|
INSERT INTO rh.p_oids (code_table, oid)
|
|
SELECT 'codes_postaux', code_postal_id
|
|
FROM rh.p_salaries
|
|
GROUP BY 1,2
|
|
;
|
|
|
|
INSERT INTO rh.p_oids (code_table, oid)
|
|
SELECT 'departements', departement_id
|
|
FROM rh.p_salaries
|
|
JOIN rh.t_codes_postaux ON (code_postal_id = t_codes_postaux.oid)
|
|
GROUP BY 1,2
|
|
;
|
|
|
|
INSERT INTO rh.p_oids (code_table, oid)
|
|
SELECT 'sections_analytiques_paie', section_analytique_paie_id
|
|
FROM rh.p_profils
|
|
GROUP BY 1,2
|
|
;
|
|
|
|
INSERT INTO rh.p_oids (code_table, oid)
|
|
SELECT 'sections_analytiques', section_analytique_id
|
|
FROM rh.p_profils
|
|
GROUP BY 1,2
|
|
;
|
|
|
|
INSERT INTO rh.p_oids (code_table, oid)
|
|
SELECT 'section_analytique', section_analytique_id
|
|
FROM rh.p_ventilation_section
|
|
GROUP BY 1,2
|
|
;
|
|
|
|
INSERT INTO rh.p_oids (code_table, oid)
|
|
SELECT 'grilles', grille_id
|
|
FROM rh.p_profils
|
|
GROUP BY 1,2
|
|
;
|
|
|
|
INSERT INTO rh.p_oids (code_table, oid)
|
|
SELECT 'grilles_groupes', grille_groupe_id
|
|
FROM rh.p_profils
|
|
GROUP BY 1,2
|
|
;
|
|
|
|
INSERT INTO rh.p_oids (code_table, oid)
|
|
SELECT 'groupes_cotisant', groupe_cotisant_id
|
|
FROM rh.p_profils
|
|
GROUP BY 1,2
|
|
;
|
|
|
|
INSERT INTO rh.p_oids (code_table, oid)
|
|
SELECT 'societes_interim', societe_interim_id
|
|
FROM rh.p_profils
|
|
GROUP BY 1,2
|
|
;
|
|
|
|
INSERT INTO rh.p_oids (code_table, oid)
|
|
SELECT 'motifs_arret', motif_arret_id
|
|
FROM rh.p_arrets_travail
|
|
GROUP BY 1,2
|
|
;
|
|
|
|
INSERT INTO rh.p_oids (code_table, oid)
|
|
SELECT 'precisions_motif_arret', precision_motif_arret_id
|
|
FROM rh.p_arrets_travail
|
|
GROUP BY 1,2
|
|
;
|
|
|
|
INSERT INTO rh.p_oids (code_table, oid)
|
|
SELECT 'rubriques', rubrique_id
|
|
FROM rh.p_historique_paie
|
|
GROUP BY 1,2
|
|
;
|
|
|
|
INSERT INTO rh.p_oids (code_table, oid)
|
|
SELECT 'organismes_cotisation', organisme_cotisation_id
|
|
FROM rh.p_historique_paie
|
|
GROUP BY 1,2
|
|
;
|
|
|
|
INSERT INTO rh.p_oids (code_table, oid)
|
|
SELECT 'motifs_visite', motif_visite_id
|
|
FROM rh.p_visites_medicales
|
|
GROUP BY 1,2
|
|
;
|
|
|
|
INSERT INTO rh.p_oids (code_table, oid)
|
|
SELECT 'accident_circonstance', accident_circonstance_id
|
|
FROM rh.p_accident_travail
|
|
GROUP BY 1,2
|
|
;
|
|
|
|
INSERT INTO rh.p_oids (code_table, oid)
|
|
SELECT 'accident_lieu', accident_lieu_id
|
|
FROM rh.p_accident_travail
|
|
GROUP BY 1,2
|
|
;
|
|
|
|
INSERT INTO rh.p_oids (code_table, oid)
|
|
SELECT 'accident_nature', accident_nature_id
|
|
FROM rh.p_accident_travail
|
|
GROUP BY 1,2
|
|
;
|
|
|
|
INSERT INTO rh.p_oids (code_table, oid)
|
|
SELECT 'accident_siege', accident_siege_id
|
|
FROM rh.p_accident_travail
|
|
GROUP BY 1,2
|
|
;
|
|
|
|
INSERT INTO rh.p_oids (code_table, oid)
|
|
SELECT 'formations', formation_id
|
|
FROM rh.p_formations
|
|
GROUP BY 1,2
|
|
;
|
|
|
|
INSERT INTO rh.p_oids (code_table, oid)
|
|
SELECT 'lettre_budgetaire', lettre_budgetaire_id
|
|
FROM rh.p_profils
|
|
GROUP BY 1,2
|
|
;
|
|
|
|
INSERT INTO rh.p_oids (code_table, oid)
|
|
SELECT 'compte_salarie', compte_salarie_id
|
|
FROM rh.p_profils
|
|
GROUP BY 1,2
|
|
;
|
|
|
|
INSERT INTO rh.p_oids (code_table, oid)
|
|
SELECT 'compte', compte_id
|
|
FROM rh.p_historique_paie
|
|
GROUP BY 1,2
|
|
;
|
|
|
|
INSERT INTO rh.p_oids (code_table, oid)
|
|
SELECT 'categorie_conge', categorie_conge_id
|
|
FROM rh.p_profils
|
|
GROUP BY 1,2
|
|
;
|
|
|
|
INSERT INTO rh.p_oids (code_table, oid)
|
|
SELECT 'commission_paritaire', commission_paritaire_id
|
|
FROM rh.p_profils
|
|
GROUP BY 1,2
|
|
;
|
|
|
|
INSERT INTO rh.p_oids (code_table, oid)
|
|
SELECT 'filiere', filiere_id
|
|
FROM rh.p_profils
|
|
GROUP BY 1,2
|
|
;
|
|
|
|
INSERT INTO rh.p_oids (code_table, oid)
|
|
SELECT 'cadre_emploi', cadre_emploi_id
|
|
FROM rh.p_profils
|
|
GROUP BY 1,2
|
|
;
|
|
|
|
INSERT INTO rh.p_oids (code_table, oid)
|
|
SELECT 'categorie_statutaire', categorie_statutaire_id
|
|
FROM rh.p_profils
|
|
GROUP BY 1,2
|
|
;
|
|
|
|
INSERT INTO rh.p_oids (code_table, oid)
|
|
SELECT 'unite_fonctionnelle', unite_fonctionnelle_id
|
|
FROM rh.p_profils
|
|
GROUP BY 1,2
|
|
;
|
|
|
|
INSERT INTO rh.p_oids (code_table, oid)
|
|
SELECT 'population', population_id[1]
|
|
FROM rh.p_profil_contrat_mois
|
|
GROUP BY 1,2
|
|
;
|
|
|
|
SELECT base.cti_stash_pop_table_constraints('rh', 'p_oids')
|
|
;
|
|
|
|
SELECT base.cti_stash_pop_table_indexes('rh', 'p_oids')
|
|
;
|
|
|
|
]]></sqlcmd>
|
|
</NODE>
|
|
|
|
<NODE label="Transformations (fonctions CTI)">
|
|
<sqlcmd><![CDATA[
|
|
|
|
-- Transformations.
|
|
SELECT rh.cti_execute_transform();
|
|
|
|
]]></sqlcmd>
|
|
</NODE>
|
|
|
|
<NODE label="OD (fonctions CTI)">
|
|
<sqlcmd><![CDATA[
|
|
|
|
-- Génération des OD.
|
|
SELECT rh.cti_gen_od();
|
|
|
|
]]></sqlcmd>
|
|
</NODE>
|
|
|
|
<NODE label="Populations (fonctions CTI)">
|
|
<sqlcmd><![CDATA[
|
|
|
|
-- Populations.
|
|
SELECT rh.cti_reorganize_population()
|
|
;
|
|
|
|
]]></sqlcmd>
|
|
</NODE>
|
|
|
|
<NODE label="Pôles (fonctions CTI)">
|
|
<sqlcmd><![CDATA[
|
|
|
|
-- Poles.
|
|
SELECT rh.cti_reorganize_pole()
|
|
;
|
|
|
|
INSERT INTO rh.p_oids (code_table, oid)
|
|
SELECT 'pole', pole_id
|
|
FROM rh.p_planning_mouvement
|
|
LEFT JOIN rh.p_oids ON p_oids.code_table = 'pole' AND p_oids.oid = p_planning_mouvement.pole_id
|
|
WHERE p_oids.oid IS NULL
|
|
GROUP BY 1,2
|
|
;
|
|
|
|
INSERT INTO rh.p_oids (code_table, oid)
|
|
SELECT 'pole', pole_id
|
|
FROM rh.p_profil_contrat_mois
|
|
LEFT JOIN rh.p_oids ON p_oids.code_table = 'pole' AND p_oids.oid = p_profil_contrat_mois.pole_id
|
|
WHERE p_oids.oid IS NULL
|
|
GROUP BY 1,2
|
|
;
|
|
|
|
]]></sqlcmd>
|
|
</NODE>
|
|
|
|
<NODE label="Classes (fonctions CTI)">
|
|
<sqlcmd><![CDATA[
|
|
|
|
ANALYZE rh.p_salaries
|
|
;
|
|
ANALYZE rh.p_profils
|
|
;
|
|
ANALYZE rh.p_ventilation_section
|
|
;
|
|
|
|
/* CLASSES */
|
|
-- Màj des classes
|
|
SELECT rh.cti_update_schema_classes('*ALL')
|
|
;
|
|
|
|
]]></sqlcmd>
|
|
</NODE>
|
|
|
|
<NODE label="SAE (fonctions CTI)">
|
|
<sqlcmd><![CDATA[
|
|
|
|
-- Ajout des contrats SAE
|
|
SELECT rh.cti_get_sae_contracts()
|
|
;
|
|
|
|
]]></sqlcmd>
|
|
</NODE>
|
|
</NODE>
|
|
<NODE name="VACUUM">
|
|
<NODE label="Réorganisation tables">
|
|
<sqlcmd><![CDATA[
|
|
|
|
SELECT base.cti_vacuum('rh.p_accident_travail');
|
|
SELECT base.cti_vacuum('rh.p_arrets_travail');
|
|
SELECT base.cti_vacuum('rh.p_arrets_travail_mois');
|
|
SELECT base.cti_vacuum('rh.p_chiffrier_production');
|
|
SELECT base.cti_vacuum('rh.p_contrats');
|
|
SELECT base.cti_vacuum('rh.p_contrats_mois');
|
|
SELECT base.cti_vacuum('rh.p_formations');
|
|
SELECT base.cti_vacuum('rh.p_handicap');
|
|
SELECT base.cti_vacuum('rh.p_historique_paie');
|
|
SELECT base.cti_vacuum('rh.p_oids');
|
|
SELECT base.cti_vacuum('rh.p_profil_contrat_mois');
|
|
SELECT base.cti_vacuum('rh.p_profils');
|
|
SELECT base.cti_vacuum('rh.p_salaries');
|
|
SELECT base.cti_vacuum('rh.p_ventilation');
|
|
SELECT base.cti_vacuum('rh.p_ventilation_section');
|
|
SELECT base.cti_vacuum('rh.p_visites_medicales');
|
|
SELECT base.cti_vacuum('rh.t_accident_circonstance');
|
|
SELECT base.cti_vacuum('rh.t_accident_lieu');
|
|
SELECT base.cti_vacuum('rh.t_accident_nature');
|
|
SELECT base.cti_vacuum('rh.t_accident_siege');
|
|
SELECT base.cti_vacuum('rh.t_cadre_emploi');
|
|
SELECT base.cti_vacuum('rh.t_categorie_conge');
|
|
SELECT base.cti_vacuum('rh.t_categorie_statutaire');
|
|
SELECT base.cti_vacuum('rh.t_categories_socio_professionnelle');
|
|
SELECT base.cti_vacuum('rh.t_codes_emploi');
|
|
SELECT base.cti_vacuum('rh.t_codes_postaux');
|
|
SELECT base.cti_vacuum('rh.t_commission_paritaire');
|
|
SELECT base.cti_vacuum('rh.t_compte');
|
|
SELECT base.cti_vacuum('rh.t_departements');
|
|
SELECT base.cti_vacuum('rh.t_entreprises');
|
|
SELECT base.cti_vacuum('rh.t_etablissements');
|
|
SELECT base.cti_vacuum('rh.t_filiere');
|
|
SELECT base.cti_vacuum('rh.t_grilles');
|
|
SELECT base.cti_vacuum('rh.t_grilles_groupes');
|
|
SELECT base.cti_vacuum('rh.t_groupes_cotisant');
|
|
SELECT base.cti_vacuum('rh.t_lettre_budgetaire');
|
|
SELECT base.cti_vacuum('rh.t_liste_formations');
|
|
SELECT base.cti_vacuum('rh.t_motifs_arret');
|
|
SELECT base.cti_vacuum('rh.t_motifs_debut_contrat');
|
|
SELECT base.cti_vacuum('rh.t_motifs_fin_contrat');
|
|
SELECT base.cti_vacuum('rh.t_motifs_visite');
|
|
SELECT base.cti_vacuum('rh.t_nationalites');
|
|
SELECT base.cti_vacuum('rh.t_organismes_cotisation');
|
|
SELECT base.cti_vacuum('rh.t_precisions_motif_arret');
|
|
SELECT base.cti_vacuum('rh.t_qualifications');
|
|
SELECT base.cti_vacuum('rh.t_rapports');
|
|
SELECT base.cti_vacuum('rh.t_rapports_rubriques');
|
|
SELECT base.cti_vacuum('rh.t_rubriques');
|
|
SELECT base.cti_vacuum('rh.t_sections_analytiques');
|
|
SELECT base.cti_vacuum('rh.t_sections_analytiques_paie');
|
|
SELECT base.cti_vacuum('rh.t_services');
|
|
SELECT base.cti_vacuum('rh.t_situations_famille');
|
|
SELECT base.cti_vacuum('rh.t_societes_interim');
|
|
SELECT base.cti_vacuum('rh.t_specialites');
|
|
SELECT base.cti_vacuum('rh.t_statuts');
|
|
SELECT base.cti_vacuum('rh.t_types_contrat');
|
|
SELECT base.cti_vacuum('rh.t_types_horaire');
|
|
SELECT base.cti_vacuum('rh.t_types_temps_travail');
|
|
SELECT base.cti_vacuum('rh.t_unite_fonctionnelle');
|
|
|
|
VACUUM ANALYSE rh.t_rapport_group;
|
|
VACUUM ANALYSE rh.t_rapports;
|
|
VACUUM ANALYSE rh.t_entreprises;
|
|
VACUUM ANALYSE rh.t_groupes_cotisant;
|
|
VACUUM ANALYSE rh.t_motifs_debut_contrat;
|
|
VACUUM ANALYSE rh.t_situations_famille;
|
|
VACUUM ANALYSE rh.t_statuts;
|
|
VACUUM ANALYSE rh.t_types_contrat;
|
|
REINDEX TABLE rh.p_personne;
|
|
REINDEX TABLE rh.p_contrats;
|
|
|
|
]]></sqlcmd>
|
|
</NODE>
|
|
</NODE>
|
|
<NODE name="RAZ">
|
|
<NODE label="Nettoyage des tables">
|
|
<sqlcmd><![CDATA[
|
|
|
|
TRUNCATE rh.p_accident_travail;
|
|
TRUNCATE rh.p_arrets_travail;
|
|
TRUNCATE rh.p_arrets_travail_mois;
|
|
TRUNCATE rh.p_chiffrier_production;
|
|
TRUNCATE rh.p_contrats;
|
|
TRUNCATE rh.p_contrats_mois;
|
|
TRUNCATE rh.p_formations;
|
|
TRUNCATE rh.p_handicap;
|
|
TRUNCATE rh.p_historique_paie;
|
|
TRUNCATE rh.p_oids;
|
|
TRUNCATE rh.p_profils;
|
|
TRUNCATE rh.p_profil_contrat_mois;
|
|
-- TRUNCATE rh.p_salaries; -- On ne supprime plus les salariés car on peut créer des listes/classes avec.
|
|
TRUNCATE rh.p_visites_medicales;
|
|
|
|
]]></sqlcmd>
|
|
</NODE>
|
|
</NODE>
|
|
<NODE name="RAZ_ALL">
|
|
<NODE label="Nettoyage COMPLET des tables">
|
|
<sqlcmd><![CDATA[
|
|
|
|
TRUNCATE rh.p_accident_travail;
|
|
TRUNCATE rh.p_arrets_travail;
|
|
TRUNCATE rh.p_arrets_travail_mois;
|
|
TRUNCATE rh.p_chiffrier_production;
|
|
TRUNCATE rh.p_contrats;
|
|
TRUNCATE rh.p_contrats_mois;
|
|
TRUNCATE rh.p_formations;
|
|
TRUNCATE rh.p_handicap;
|
|
TRUNCATE rh.p_historique_paie;
|
|
TRUNCATE rh.p_oids;
|
|
TRUNCATE rh.p_profil_contrat_mois;
|
|
TRUNCATE rh.p_profils;
|
|
TRUNCATE rh.p_salaries;
|
|
TRUNCATE rh.p_visites_medicales;
|
|
TRUNCATE rh.t_accident_circonstance;
|
|
TRUNCATE rh.t_accident_lieu;
|
|
TRUNCATE rh.t_accident_nature;
|
|
TRUNCATE rh.t_accident_siege;
|
|
TRUNCATE rh.t_cadre_emploi;
|
|
TRUNCATE rh.t_categorie_conge;
|
|
TRUNCATE rh.t_categorie_statutaire;
|
|
TRUNCATE rh.t_categories_socio_professionnelle;
|
|
TRUNCATE rh.t_codes_emploi;
|
|
TRUNCATE rh.t_codes_postaux;
|
|
TRUNCATE rh.t_commission_paritaire;
|
|
TRUNCATE rh.t_compte;
|
|
TRUNCATE rh.t_departements;
|
|
TRUNCATE rh.t_entreprises;
|
|
TRUNCATE rh.t_etablissements;
|
|
TRUNCATE rh.t_filiere;
|
|
TRUNCATE rh.t_grilles;
|
|
TRUNCATE rh.t_grilles_groupes;
|
|
TRUNCATE rh.t_groupes_cotisant;
|
|
TRUNCATE rh.t_lettre_budgetaire;
|
|
TRUNCATE rh.t_liste_formations;
|
|
TRUNCATE rh.t_motifs_arret;
|
|
TRUNCATE rh.t_motifs_debut_contrat;
|
|
TRUNCATE rh.t_motifs_fin_contrat;
|
|
TRUNCATE rh.t_motifs_visite;
|
|
TRUNCATE rh.t_nationalites;
|
|
TRUNCATE rh.t_organismes_cotisation;
|
|
TRUNCATE rh.t_precisions_motif_arret;
|
|
TRUNCATE rh.t_qualifications;
|
|
TRUNCATE rh.t_rapports;
|
|
TRUNCATE rh.t_rapports_rubriques;
|
|
TRUNCATE rh.t_rubriques;
|
|
TRUNCATE rh.t_sections_analytiques;
|
|
TRUNCATE rh.t_sections_analytiques_paie;
|
|
TRUNCATE rh.t_services;
|
|
TRUNCATE rh.t_situations_famille;
|
|
TRUNCATE rh.t_societes_interim;
|
|
TRUNCATE rh.t_specialites;
|
|
TRUNCATE rh.t_statuts;
|
|
TRUNCATE rh.t_types_contrat;
|
|
TRUNCATE rh.t_types_horaire;
|
|
TRUNCATE rh.t_types_temps_travail;
|
|
TRUNCATE rh.t_unite_fonctionnelle;
|
|
|
|
]]></sqlcmd>
|
|
</NODE>
|
|
</NODE>
|
|
</ROOT>
|