= rhp('rhprovider_start')::date group by 1,2 ; ]]> = rhp('rhprovider_start')::date AND t_etablissements.oid != 0 GROUP BY 1,2 ) SELECT nextval('s_bulletins'::regclass) AS bulletin_id, entreprise_id, etablissement_id, 'BULLETIN' || '-' || matricule || '-' || mois AS numero_bulletin, date_debut, date_fin, mois, matricule, resbru, rehpay, rehtra, 0::bigint AS affectation_contrat_mois_id, 0::int AS est_hors_periode_contrat FROM gestion_multi_bulletins ) ; ]]> = 151.67 then 'TC' else 'TP' end||round(cnhmens::numeric, 2)::text, chr(1)||'*') AS type_temps_travail, coalesce(nullif(cnhmens / 151.67, 0), 1.0) AS etp_theorique, 0::int AS est_hors_periode, dernier_bulletin_salaries.date_fin_dernier_bulletin FROM prod_adp.contrat JOIN w_sal_ets ON w_sal_ets.etcmat = contrat.etcmat -- Limiter la remontée des contrats aux seuls salariés ayant un bulletin JOIN rh.t_divers ON code = 'ADP_TYPE_CONTRAT' LEFT JOIN dernier_bulletin_salaries ON dernier_bulletin_salaries.matricule = contrat.etcmat WHERE (cnlcnt != '' OR lnmcnt != '') -- exclu les contrats "en erreur". ORDER BY H1DDEB ) ; ]]> = 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 w_bulletins.date_debut BETWEEN w_contrats.date_debut_contrat AND w_contrats.date_fin_contrat 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') ) ; ]]> 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 substr(md5(act_motif_debut), 1, 5), substr(md5(act_motif_debut), 1, 5), act_motif_debut, substr(max(act_motif_debut),1,50) FROM prod_adp.contrat WHERE substr(md5(act_motif_debut), 1, 5) NOT IN (SELECT code_original FROM rh.t_motifs_debut_contrat WHERE code_original IS NOT NULL) GROUP BY 1,2,3 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 motif_fin_code, motif_fin_code, MAX(motif_fin_texte), substr(MAX(motif_fin_texte), 1, 50) FROM w_contrats_mois WHERE motif_fin_code <> chr(1)||'*' AND motif_fin_code NOT IN (SELECT code_original FROM rh.t_motifs_fin_contrat WHERE code_original IS NOT NULL) GROUP BY 1,2 ; -- Màj des nationalités. INSERT INTO rh.t_nationalites(code, texte, texte_court, code_original) SELECT etcnat, max(etlnat), max(substr(etlnat,1,50)), etcnat FROM prod_adp.etaciv WHERE etcnat NOT IN (SELECT code_original FROM rh.t_nationalites WHERE code_original IS NOT NULL) GROUP BY 1,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, rang_edition) select rubid, rubid, libelle, substr(libelle, 1, 50), noordre from prod_adp.rgl_pp_tabrub WHERE rubid NOT IN (SELECT code_original FROM rh.t_rubriques WHERE code_original IS NOT NULL) GROUP BY 1,2,3,4,5 ; -- Màj des situations de famille INSERT INTO rh.t_situations_famille(code_original, code, texte_court, texte) SELECT etcsfa, etcsfa, MAX(substr(etlsfa,1,50)), MAX(etlsfa) FROM prod_adp.etaciv WHERE etcsfa NOT IN (SELECT code_original FROM rh.t_situations_famille WHERE code_original IS NOT NULL) GROUP BY 1,2 ; -- 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 ; -- Màj des codes emploi. avec LTR ADP ELSAN. INSERT INTO rh.t_codes_emploi(code_original, code, texte, texte_court) SELECT code_emploi_code, code_emploi_code, max(code_emploi_texte), max(substr(code_emploi_texte, 1, 50)) FROM w_contrats_mois WHERE code_emploi_code <> chr(1)||'*' AND code_emploi_code NOT IN (SELECT code_original FROM rh.t_codes_emploi WHERE code_original IS NOT NULL) GROUP BY 1,2 ; -- Màj des groupes de grilles INSERT INTO rh.t_grilles_groupes(code_original, code, texte, texte_court) SELECT grille_groupe_code, grille_groupe_code, max(grille_groupe_texte), max(substr(grille_groupe_texte, 1, 50)) FROM w_contrats_mois WHERE grille_groupe_code <> chr(1)||'*' AND grille_groupe_code NOT IN (SELECT code_original FROM rh.t_grilles_groupes WHERE code_original IS NOT NULL) GROUP BY 1,2 ; ]]> = rhp('rhprovider_start')::date -- Filtrer les lignes générées systématiquement tous les mois par Sage pour chaque salarié méme s'il n'y a rien. AND (false OR p_nombre OR p_base OR p_heures_contrat OR p_heures_payees OR p_heures_travaillees OR p_masse_salariale OR p_brut OR p_avantage_nature OR p_frais_imposables OR p_cotisation_salarie OR p_cotisation_patronale OR p_od_net_salarie OR p_od_net_patronale OR p_net_imposable OR p_net_a_payer OR p_nombre_provisions OR p_montant_provisions OR p_masse_salariale_provisionnee) ; ]]> = 1 ; ]]> 1 ) subview ON p_salaries.nir = subview.nir WHERE p_salaries.oid <> subview.to_oid ; ANALYSE w_map_doublons ; UPDATE rh.p_accident_travail SET salarie_id = to_oid FROM w_map_doublons WHERE salarie_id = from_oid ; UPDATE rh.p_arrets_travail SET salarie_id = to_oid FROM w_map_doublons WHERE salarie_id = from_oid ; UPDATE rh.p_arrets_travail_mois SET salarie_id = to_oid FROM w_map_doublons WHERE salarie_id = from_oid ; UPDATE rh.p_contrats SET salarie_id = to_oid FROM w_map_doublons WHERE salarie_id = from_oid ; UPDATE rh.p_contrats_mois SET salarie_id = to_oid FROM w_map_doublons WHERE salarie_id = from_oid ; UPDATE rh.p_handicap SET salarie_id = to_oid FROM w_map_doublons WHERE salarie_id = from_oid ; UPDATE rh.p_handicap2 SET salarie_id = to_oid FROM w_map_doublons WHERE salarie_id = from_oid ; UPDATE rh.p_historique_paie SET salarie_id = to_oid FROM w_map_doublons WHERE salarie_id = from_oid ; UPDATE rh.p_profil_contrat_mois SET salarie_id = to_oid FROM w_map_doublons WHERE salarie_id = from_oid ; DELETE FROM rh.p_salaries USING w_map_doublons WHERE oid = from_oid ; ]]>