= rhp('rhprovider_start')::date GROUP BY 1 ; ]]> = rhp('rhprovider_start')::date GROUP BY 1,2 ) SELECT nextval('s_bulletins'::regclass) AS bulletin_id, t_etablissements.entreprise_id, t_etablissements.oid AS etablissement_id, 'BULLETIN' || '-' || matricule || '-' || mois AS numero_bulletin, date_debut, date_fin, mois, matricule, total_brut, total_heures_payees, total_heures_travaillees, 0::int AS affectation_contrat_mois_id, 0::int AS est_hors_periode_contrat FROM gestion_multi_bulletins JOIN rh.t_etablissements ON t_etablissements.code_original::numeric = right(gestion_multi_bulletins.code_etablissement, 4) WHERE t_etablissements.oid != 0 ) ; ]]> = 151.67 then 'TC' else 'TP' end||round(contrats.nombres_heures_contractuelles::numeric, 2)::text, chr(1)||'*') AS type_temps_travail, coalesce(nullif(contrats.nombres_heures_contractuelles::numeric / 151.67, 0), 1.0) AS etp_theorique, 0::int AS est_hors_periode, dernier_bulletin_salaries.date_fin_dernier_bulletin FROM contrats JOIN w_sal_ets ON w_sal_ets.matricule = contrats.matricule -- Limiter la remontée des contrats aux seuls salariés ayant un bulletin JOIN dernier_bulletin_salaries ON dernier_bulletin_salaries.matricule = contrats.matricule ORDER BY contrats.date_debut_contrat::date ) ; ]]> = w_contrats.date_debut_contrat AND w_bulletins.date_fin <= w_contrats.date_fin_contrat ; -- Si etablissement_id restant à 0, on renseigne le dernier id connu dans les contrats UPDATE w_contrats SET etablissement_id = subview.etablissement_id, entreprise_id = subview.entreprise_id FROM ( SELECT matricule, (MAX(array[w_contrats.date_fin_contrat::text, w_contrats.etablissement_id::text]))[2]::int AS etablissement_id, (MAX(array[w_contrats.date_fin_contrat::text, w_contrats.entreprise_id::text]))[2]::int AS entreprise_id FROM w_contrats WHERE etablissement_id <> 0 GROUP BY 1 ) AS subview WHERE w_contrats.etablissement_id = 0 AND w_contrats.matricule = subview.matricule ; -- Si etablissement_id restant à 0, on renseigne l'établissement le plus récent UPDATE w_contrats SET etablissement_id = subview.etablissement_id, entreprise_id = subview.entreprise_id FROM ( SELECT matricule, (MAX(array[w_bulletins.date_fin::text, w_bulletins.etablissement_id::text]))[2]::int AS etablissement_id, (MAX(array[w_bulletins.date_fin::text, w_bulletins.entreprise_id::text]))[2]::int AS entreprise_id FROM w_bulletins GROUP BY 1 ) AS subview WHERE w_contrats.etablissement_id = 0 AND w_contrats.matricule = subview.matricule ; ANALYZE w_contrats ; -- Mise à jours des bulletins hors période de contrat UPDATE w_bulletins SET est_hors_periode_contrat = 1 FROM ( SELECT w_bulletins.matricule, w_bulletins.bulletin_id FROM w_bulletins LEFT JOIN w_contrats ON w_contrats.matricule = w_bulletins.matricule AND base.cti_overlaps(w_contrats.date_debut_contrat, w_contrats.date_fin_contrat, w_bulletins.date_debut, w_bulletins.date_fin) WHERE w_contrats.contrat_id IS NULL ) AS subview WHERE w_bulletins.matricule = subview.matricule AND w_bulletins.bulletin_id = subview.bulletin_id ; ANALYZE w_bulletins ; ]]> = (rhp('rhprovider_start')::date - interval '2 YEAR') ) ; ]]> = positp.date_debut::date ) ; -- Récupération pour chaque contrat_mois des informations les plus récentes du salarié DROP TABLE IF EXISTS dernieres_infos_contrat_mois ; CREATE TEMP TABLE dernieres_infos_contrat_mois AS with dernieres_infos_par_contrat_mois AS ( SELECT w_contrats_mois.contrat_mois_id, (MAX(ARRAY[EXTRACT(EPOCH FROM w_infos_positp.date_debut), w_infos_positp.id]))[2] AS dernier_infos_positp_id FROM w_contrats_mois LEFT JOIN w_infos_positp ON w_infos_positp.contrat_mois_id = w_contrats_mois.contrat_mois_id GROUP BY 1 ) SELECT w_contrats_mois.contrat_mois_id, w_infos_positp.qualification_code, w_infos_positp.qualification_texte, w_infos_positp.statut_code, w_infos_positp.statut_texte FROM w_contrats_mois LEFT JOIN dernieres_infos_par_contrat_mois ON dernieres_infos_par_contrat_mois.contrat_mois_id = w_contrats_mois.contrat_mois_id LEFT JOIN w_infos_positp ON w_infos_positp.contrat_mois_id = w_contrats_mois.contrat_mois_id AND w_infos_positp.id = dernieres_infos_par_contrat_mois.dernier_infos_positp_id ; -- Mise à jour des éléments de positp et sadmin sur les contrats_mois UPDATE w_contrats_mois SET qualification_code = COALESCE(dernieres_infos_contrat_mois.qualification_code, chr(1)||'*'), qualification_texte = COALESCE(dernieres_infos_contrat_mois.qualification_texte, chr(1)||'*'), statut_code = COALESCE(dernieres_infos_contrat_mois.statut_code, chr(1)||'*'), statut_texte = COALESCE(dernieres_infos_contrat_mois.statut_texte, chr(1)||'*') FROM dernieres_infos_contrat_mois WHERE dernieres_infos_contrat_mois.contrat_mois_id = w_contrats_mois.contrat_mois_id ; ANALYZE w_contrats_mois ; ]]> base.cti_first_day(w_contrats_mois.date_debut_contrat_mois) then 0 else 1 end AS present_debut_mois, case when w_contrats_mois.date_fin_contrat < base.cti_last_day(w_contrats_mois.date_debut_contrat_mois) then 0 else 1 end AS present_fin_mois, w_contrats_mois.etp_theorique AS equivalent_temps_plein, w_contrats_mois.date_fin_contrat_mois - coalesce(p_salaries.date_naissance, '1962-04-18'::date) AS age_jours, w_contrats_mois.etablissement_id FROM rh.p_contrats JOIN w_contrats_mois on w_contrats_mois.contrat_id = p_contrats.oid JOIN rh.p_salaries on p_salaries.oid = w_contrats_mois.salarie_id ; ]]> chr(1)||'*' AND categorie_socio_professionnelle_code NOT IN (SELECT code_original FROM rh.t_categories_socio_professionnelle WHERE code_original IS NOT NULL) GROUP BY 1,2,3,4 ; -- Màj des motifs de début de contrat. INSERT INTO rh.t_motifs_debut_contrat(code_original, code, texte, texte_court) SELECT code_motif_debut_contrat, code_motif_debut_contrat, libelle_motif_debut_contrat, substr(libelle_motif_debut_contrat,1,50) FROM prod_cegidhru_melioris.contrat WHERE code_motif_debut_contrat NOT IN (SELECT code_original FROM rh.t_motifs_debut_contrat WHERE code_original IS NOT NULL) GROUP BY 1,2,3,4 ORDER BY 2 ; -- Màj des motifs de fin de contrat. INSERT INTO rh.t_motifs_fin_contrat(code_original, code, texte, texte_court) SELECT code_motif_fin_contrat, code_motif_fin_contrat, libelle_motif_fin_contrat, substr(libelle_motif_fin_contrat,1,50) FROM prod_cegidhru_melioris.contrat WHERE code_motif_fin_contrat NOT IN (SELECT code_original FROM rh.t_motifs_fin_contrat WHERE code_original IS NOT NULL) GROUP BY 1,2,3,4 ORDER BY 2 ; -- Màj des nationalités. INSERT INTO rh.t_nationalites(code, code_original, texte, texte_court) SELECT code_nationalite, code_nationalite, libelle_nationalite, substr(libelle_nationalite,1,50) FROM prod_cegidhru_melioris.etat_civil WHERE code_nationalite NOT IN (SELECT code_original FROM rh.t_nationalites WHERE code_original IS NOT NULL) GROUP BY 1,2,3,4 ; -- Màj des qualifications INSERT INTO rh.t_qualifications(code_original, code, texte, texte_court) SELECT qualification_code, qualification_code, max(qualification_texte), substr(max(qualification_texte), 1, 50) FROM w_contrats_mois WHERE qualification_code <> chr(1)||'*' AND qualification_code NOT IN (SELECT code_original FROM rh.t_qualifications WHERE code_original IS NOT NULL) GROUP BY 1,2 ; -- Màj des rubriques INSERT INTO rh.t_rubriques(code_original, code, texte, texte_court) SELECT code_rubrique, code_rubrique, libelle_rubrique, substr(libelle_rubrique, 1, 50) FROM prod_cegidhru_melioris.rubrique WHERE code_rubrique NOT IN (SELECT code_original FROM rh.t_rubriques WHERE code_original IS NOT NULL) GROUP BY 1,2,3,4 ; -- Màj des situations de famille INSERT INTO rh.t_situations_famille(code_original, code, texte, texte_court) SELECT code_situation_familiale, code_situation_familiale, libelle_situation_familiale, substr(libelle_situation_familiale, 1, 50) FROM prod_cegidhru_melioris.etat_civil WHERE code_situation_familiale NOT IN (SELECT code_original FROM rh.t_situations_famille WHERE code_original IS NOT NULL) GROUP BY 1,2,3,4 ; -- Màj des types de contrat INSERT INTO rh.t_types_contrat(code_original, code, texte, texte_court) SELECT type_contrat_code, type_contrat_code, type_contrat_texte, substr(type_contrat_texte, 1, 50) FROM w_contrats_mois WHERE type_contrat_code <> chr(1)||'*' AND type_contrat_code NOT IN (SELECT code_original FROM rh.t_types_contrat WHERE code_original IS NOT NULL) GROUP BY 1,2,3,4 ; -- Màj des statuts INSERT INTO rh.t_statuts(code_original, code, texte, texte_court) SELECT statut_code, statut_code, statut_texte, substr(statut_texte, 1, 50) FROM w_contrats_mois WHERE statut_code <> chr(1)||'*' AND statut_code NOT IN (SELECT code_original FROM rh.t_statuts WHERE code_original IS NOT NULL) GROUP BY 1,2,3,4 ; -- Màj des types de temps de travail INSERT INTO rh.t_types_temps_travail(code_original, code, texte, texte_court) SELECT CASE WHEN heures_theoriques >= 151.67 THEN 'TC' ELSE 'TP' END||ROUND(heures_theoriques::numeric, 2)::text, CASE WHEN heures_theoriques >= 151.67 THEN 'TC' ELSE 'TP' END||ROUND(heures_theoriques::numeric, 2)::text, CASE WHEN heures_theoriques >= 151.67 THEN 'Temps Complet ' ELSE 'Temps Partiel ' end||round(heures_theoriques::numeric, 2)::text, CASE WHEN heures_theoriques >= 151.67 THEN 'TC ' ELSE 'TP ' END||ROUND(heures_theoriques::numeric, 2)::text FROM w_contrats_mois WHERE CASE WHEN heures_theoriques >= 151.67 THEN 'TC' ELSE 'TP' END||ROUND(heures_theoriques::numeric, 2)::text NOT IN (SELECT code_original FROM rh.t_types_temps_travail WHERE code_original IS NOT NULL) GROUP BY 1,2,3,4 ; -- Màj des services INSERT INTO rh.t_services(code_original, code, texte, texte_court) SELECT service_code, service_code, max(service_texte), max(substr(service_texte, 1, 50)) FROM w_contrats_mois WHERE service_code <> chr(1)||'*' AND service_code NOT IN (SELECT code_original FROM rh.t_services WHERE code_original IS NOT NULL) GROUP BY 1,2 ; ]]> = rhp('rhprovider_start')::date ; ]]>