'' GROUP BY 1 ; UPDATE temp.x_ref_qualification SET texte = replace(texte,'(E )','(E)'), texte_court = replace(texte,'(E )','(E)') WHERE texte LIKE '%(E )%' ; UPDATE temp.x_ref_qualification SET code = UPPER( substr(split_part(texte,' ',1),1,3) || substr(split_part(texte,' ',2),1,3) || substr(split_part(texte,' ',3),1,3) || substr(split_part(texte,' ',4),1,3) ) ; -- Identification des Comptes DROP TABLE IF EXISTS temp.x_ref_compte ; CREATE TABLE temp.x_ref_compte AS SELECT IDENT2_0 AS code_original, MAX(IDENT2_0) AS code, MAX(CASE WHEN ZONE_0 = 'DESTRA' THEN TEXTE_0 ELSE '' END) AS texte, MAX(CASE WHEN ZONE_0 = 'SHOTRA' THEN TEXTE_0 ELSE '' END) AS texte_court FROM prod_sagex3rhp.ATEXTRA WHERE 1=1 AND LANGUE_0 = 'FRA' AND CODFIC_0 = 'GACCOUNT' GROUP BY 1 ; -- Identification des situations de famille DROP TABLE IF EXISTS temp.x_ref_situation_famille ; CREATE TABLE temp.x_ref_situation_famille AS SELECT IDENT2_0 AS code_original, MAX(IDENT2_0) AS code, MAX(CASE WHEN ZONE_0 = 'LNGDES' THEN TEXTE_0 ELSE '' END) AS texte, MAX(CASE WHEN ZONE_0 = 'SHODES' THEN TEXTE_0 ELSE '' END) AS texte_court FROM prod_sagex3rhp.ATEXTRA WHERE 1=1 AND LANGUE_0 = 'FRA' AND CODFIC_0 = 'ATABDIV' AND IDENT1_0 = '346' GROUP BY 1 ; -- Identification des statuts DROP TABLE IF EXISTS temp.x_ref_statut ; CREATE TABLE temp.x_ref_statut AS SELECT IDENT2_0 AS code_original, MAX(IDENT2_0) AS code, MAX(CASE WHEN ZONE_0 = 'LNGDES' THEN TEXTE_0 ELSE '' END) AS texte, MAX(CASE WHEN ZONE_0 = 'SHODES' THEN TEXTE_0 ELSE '' END) AS texte_court FROM prod_sagex3rhp.ATEXTRA WHERE 1=1 AND LANGUE_0 = 'FRA' AND CODFIC_0 = 'ATABDIV' AND IDENT1_0 = '364' GROUP BY 1 ; -- Identification des types de temps de travail DROP TABLE IF EXISTS temp.x_ref_type_temps_travail ; CREATE TABLE temp.x_ref_type_temps_travail AS SELECT CASE WHEN round(HRSMTH_0/151.67,2) = 1 THEN 'TC' ELSE 'TP'||lpad((round(HRSMTH_0/151.67, 2) * 100)::int, 2, '0') END AS code_original, MAX(CASE WHEN round(HRSMTH_0/151.67,2) = 1 THEN 'TC' ELSE 'TP'||lpad((round(HRSMTH_0/151.67, 2) * 100)::int, 2, '0') END) AS code, MAX(CASE WHEN round(HRSMTH_0/151.67,2) = 1 THEN 'Temps Complet' ELSE 'Temps Partiel '||lpad((round(HRSMTH_0/151.67, 2) * 100)::int, 2, '0')||' %' END) AS texte, MAX(CASE WHEN round(HRSMTH_0/151.67,2) = 1 THEN 'TC' ELSE 'TP' END) AS texte_court FROM prod_sagex3rhp.EMPLOCTR GROUP BY 1 ; -- Identification des services DROP TABLE IF EXISTS temp.x_ref_service ; CREATE TABLE temp.x_ref_service AS SELECT COD_0 AS code_original, MAX(COD_0) AS code, MAX(DES_0) AS texte, MAX(DESSHO_0) AS texte_court FROM prod_sagex3rhp.SERVICE GROUP BY 1 ; -- Identification des spécialités DROP TABLE IF EXISTS temp.x_ref_specialite ; CREATE TABLE temp.x_ref_specialite AS SELECT IDENT2_0 AS code_original, MAX(IDENT2_0) AS code, MAX(CASE WHEN ZONE_0 = 'LNGDES' THEN TEXTE_0 ELSE '' END) AS texte, MAX(CASE WHEN ZONE_0 = 'SHODES' THEN TEXTE_0 ELSE '' END) AS texte_court FROM prod_sagex3rhp.ATEXTRA WHERE 1=1 AND LANGUE_0 = 'FRA' AND CODFIC_0 = 'ATABDIV' AND IDENT1_0 = '392' GROUP BY 1 ; -- Identification des codes emploi DROP TABLE IF EXISTS temp.x_ref_code_emploi ; CREATE TABLE temp.x_ref_code_emploi AS SELECT IDENT2_0 AS code_original, MAX(IDENT2_0) AS code, MAX(CASE WHEN ZONE_0 = 'LNGDES' THEN TEXTE_0 ELSE '' END) AS texte, MAX(CASE WHEN ZONE_0 = 'SHODES' THEN TEXTE_0 ELSE '' END) AS texte_court FROM prod_sagex3rhp.ATEXTRA WHERE 1=1 AND LANGUE_0 = 'FRA' AND CODFIC_0 = 'ATABDIV' AND IDENT1_0 = '357' GROUP BY 1 ; -- Identification des types d'horaire DROP TABLE IF EXISTS temp.x_ref_type_horaire ; CREATE TABLE temp.x_ref_type_horaire AS SELECT IDENT2_0 AS code_original, MAX(IDENT2_0) AS code, MAX(CASE WHEN ZONE_0 = 'LNGDES' THEN TEXTE_0 ELSE '' END) AS texte, MAX(CASE WHEN ZONE_0 = 'SHODES' THEN TEXTE_0 ELSE '' END) AS texte_court FROM prod_sagex3rhp.ATEXTRA WHERE 1=1 AND LANGUE_0 = 'FRA' AND CODFIC_0 = 'ATABDIV' AND IDENT1_0 = '6004' GROUP BY 1 ; -- Identification des grilles DROP TABLE IF EXISTS temp.x_ref_grille ; CREATE TABLE temp.x_ref_grille AS select null::text AS code_original, null::text AS code, null::text AS texte, null::text AS texte_court limit 0 ; -- Identification des groupes de grilles -- Identification des motifs d'arret DROP TABLE IF EXISTS temp.x_ref_motif_arret ; CREATE TABLE temp.x_ref_motif_arret AS SELECT IDENT2_0 AS code_original, MAX(IDENT2_0) AS code, MAX(CASE WHEN ZONE_0 = 'LNGDES' THEN TEXTE_0 ELSE '' END) AS texte, MAX(CASE WHEN ZONE_0 = 'SHODES' THEN TEXTE_0 ELSE '' END) AS texte_court FROM prod_sagex3rhp.ATEXTRA WHERE 1=1 AND LANGUE_0 = 'FRA' AND CODFIC_0 = 'ATABDIV' AND IDENT1_0 = '396' GROUP BY 1 ; -- Identification des précisions du motif d'arrêt -- Identification des motifs de visite médicale DROP TABLE IF EXISTS temp.x_ref_motif_visite ; CREATE TABLE temp.x_ref_motif_visite AS SELECT IDENT2_0 AS code_original, MAX(IDENT2_0) AS code, MAX(CASE WHEN ZONE_0 = 'LNGDES' THEN TEXTE_0 ELSE '' END) AS texte, MAX(CASE WHEN ZONE_0 = 'SHODES' THEN TEXTE_0 ELSE '' END) AS texte_court FROM prod_sagex3rhp.ATEXTRA WHERE 1=1 AND LANGUE_0 = 'FRA' AND CODFIC_0 = 'ATABDIV' AND IDENT1_0 = '395' GROUP BY 1 ; -- Identification des circonstances d'accident du travail -- Identification des lieux d'accident du travail -- Identification de la nature de l'accident du travail -- Identification des sièges d'accident du travail -- Identification des listes de formations DROP TABLE IF EXISTS temp.x_ref_liste_formation ; CREATE TABLE temp.x_ref_liste_formation AS SELECT COD_0 AS code_original, MAX(COD_0) AS code, MAX(DES_0) AS texte, NULL::text AS texte_court FROM prod_sagex3rhp.STAGE GROUP BY 1 ; -- Identification des sections analytiques DROP TABLE IF EXISTS temp.x_ref_section_analytique ; CREATE TABLE temp.x_ref_section_analytique AS SELECT CCE_0 AS code_original, MAX(CCE_0) AS code, MAX(DES_0) AS texte, MAX(DESSHO_0) AS texte_court FROM prod_sagex3rhp.CACCE GROUP BY 1 ; -- Identification des rubriques de paie. DROP TABLE IF EXISTS w_RUBRIQUE; CREATE TEMP TABLE w_RUBRIQUE AS SELECT COD_0, MAX(RUBRIQUE.ROW_0) AS ROW_0, MAX(DES_0) AS DES_0, MAX(DES_0) AS DESSHO_0, MAX(AMTPRN_0) AS AMTPRN_0, MAX(ARRAY[CUM_0,CUM_1,CUM_2,CUM_3,CUM_4,CUM_5,CUM_6,CUM_7,CUM_8,CUM_9]) AS CUM_x, MAX(CASE WHEN HISTOPAYE.TYP_0 = 1 THEN '1' WHEN HISTOPAYE.TYP_0 = 7 THEN '1' ELSE '0' END) AS TYP_1, MAX(CASE WHEN HISTOPAYE.TYP_0 = 2 THEN '1' ELSE '0' END) AS TYP_2, MAX( CASE RUB_0 WHEN 'HRES_EFF' THEN '2' WHEN 'HRES_PAY' THEN '2' WHEN 'HRES_SAL' THEN '2' WHEN 'NET_IMPOS' THEN '1' WHEN 'NET_PAYER' THEN '1' WHEN 'CHARGES' THEN '1' WHEN 'RETENUES' THEN '1' WHEN 'BRUT' THEN '1' ELSE '0' END::text ) AS is_total FROM prod_sagex3rhp.HISTOPAYE JOIN prod_sagex3rhp.RUBRIQUE ON HISTOPAYE.RUB_0 = RUBRIQUE.COD_0 WHERE (HISTOPAYE.TYP_0 IN (1,2,7) AND AMTPRN_0 BETWEEN 1 AND 5) OR RUB_0 IN ('HRES_EFF','HRES_PAY','HRES_SAL','BRUT','CHARGES','RETENUES') GROUP BY 1 ; DROP TABLE IF EXISTS temp.x_ref_rubrique ; CREATE TABLE temp.x_ref_rubrique AS SELECT COD_0::text AS code_original, to_char(ROW_0,'FM9900000') AS code, DES_0 AS texte, DESSHO_0 AS texte_court, ROW_0::int AS rang_edition, is_total IN ('1','2') AS p_cumul, is_total IN ('0','2') AS p_detail, false AS p_nombre, 0 AS s_nombre, 1 AS c_nombre, true AS p_base, 1 AS s_base, 1 AS c_base, COD_0 = 'HRES_SAL' AS p_heures_contrat, 1 AS s_heures_contrat, 1 AS c_heures_contrat, COD_0 = 'HRES_PAY' AS p_heures_payees, 1 AS s_heures_payees, 1 AS c_heures_payees, COD_0 = 'HRES_EFF' AS p_heures_travaillees, 1 AS s_heures_travaillees, 1 AS c_heures_travaillees, COD_0 = 'BRUT' OR COD_0 = 'CHARGES' OR (AMTPRN_0 BETWEEN 2 AND 5 AND ('TOTBRUT' = ANY(CUM_x) OR 'TOTCHARGE' = ANY(CUM_x))) AS p_masse_salariale, CASE WHEN COD_0 = 'BRUT' THEN 3 WHEN AMTPRN_0 BETWEEN 2 AND 5 AND 'TOTBRUT' = ANY(CUM_x) THEN 3 WHEN COD_0 = 'CHARGES' THEN 5 WHEN AMTPRN_0 BETWEEN 2 AND 5 AND 'TOTCHARGE' = ANY(CUM_x) THEN 5 ELSE NULL END AS s_masse_salariale, CASE WHEN 'TOTBRUT' = ANY(CUM_x) AND AMTPRN_0 IN (3,5) THEN -1 ELSE 1 END AS c_masse_salariale, COD_0 = 'BRUT' OR (AMTPRN_0 BETWEEN 2 AND 5 AND 'TOTBRUT' = ANY(CUM_x)) AS p_brut, 3 AS s_brut, CASE WHEN AMTPRN_0 IN (3,5) THEN -1 ELSE 1 END AS c_brut, false AS p_avantage_nature, 3 AS s_avantage_nature, 1 AS c_avantage_nature, false AS p_frais_imposables, 3 AS s_frais_imposables, 1 AS c_frais_imposables, COD_0 = 'RETENUES' OR (AMTPRN_0 BETWEEN 2 AND 5 AND 'TOTRETENU' = ANY(CUM_x) AND TYP_1 = '1') AS p_cotisation_salarie, 3 AS s_cotisation_salarie, 1 AS c_cotisation_salarie, COD_0 = 'CHARGES' OR (AMTPRN_0 BETWEEN 2 AND 5 AND 'TOTCHARGE' = ANY(CUM_x) AND TYP_2 = '1') AS p_cotisation_patronale, 5 AS s_cotisation_patronale, 1 AS c_cotisation_patronale, false AS p_od_net_salarie, 3 AS s_od_net_salarie, 1 AS c_od_net_salarie, AMTPRN_0 BETWEEN 2 AND 5 AND ('TOTNAP' = ANY(CUM_x) AND TYP_2 = '1') AS p_od_net_patronale, 5 AS s_od_net_patronale, 1 AS c_od_net_patronale, COD_0 = 'NET_IMPOS' OR (AMTPRN_0 BETWEEN 2 AND 5 AND 'TOTBRUT' = ANY(CUM_x)) OR (AMTPRN_0 BETWEEN 2 AND 5 AND 'TOTRETENU' = ANY(CUM_x) AND TYP_1 = '1') AS p_net_imposable, 3 AS s_net_imposable, CASE WHEN 'TOTBRUT' = ANY(CUM_x) AND AMTPRN_0 IN (3,5) THEN -1 WHEN 'TOTBRUT' = ANY(CUM_x) AND AMTPRN_0 NOT IN (3,5) THEN 1 WHEN 'TOTRETENU' = ANY(CUM_x) AND TYP_1 = '1' AND AMTPRN_0 BETWEEN 2 AND 5 THEN -1 ELSE 1 END AS c_net_imposable, COD_0 = 'NET_PAYER' OR (AMTPRN_0 BETWEEN 2 AND 5 AND 'TOTBRUT' = ANY(CUM_x)) OR (AMTPRN_0 BETWEEN 2 AND 5 AND 'TOTRETENU' = ANY(CUM_x) AND TYP_1 = '1') AS p_net_a_payer, 3 AS s_net_a_payer, CASE WHEN 'TOTBRUT' = ANY(CUM_x) AND AMTPRN_0 IN (3,5) THEN -1 WHEN 'TOTBRUT' = ANY(CUM_x) AND AMTPRN_0 NOT IN (3,5) THEN 1 WHEN 'TOTRETENU' = ANY(CUM_x) AND TYP_1 = '1' AND AMTPRN_0 BETWEEN 2 AND 5 THEN -1 ELSE 1 END AS c_net_a_payer FROM w_RUBRIQUE ; WITH rub_cum_0 AS ( SELECT 'C000' AS code, 'Ecart cumulé' AS texte UNION ALL SELECT 'C001' AS code, 'Heures payées' AS texte UNION ALL SELECT 'C002' AS code, 'Heures travaillées' AS texte UNION ALL SELECT 'C003' AS code, 'Net à payer' AS texte UNION ALL SELECT 'C004' AS code, 'Net imposable' AS texte UNION ALL SELECT 'C005' AS code, 'Avantage en nature' AS texte UNION ALL SELECT 'C006' AS code, 'Cotisations patronales' AS texte UNION ALL SELECT 'C007' AS code, 'Cotisations salariales' AS texte UNION ALL SELECT 'C008' AS code, 'Brut' AS texte UNION ALL SELECT 'C009' AS code, 'Heures Cadres Forfaits Jours' AS texte ) INSERT INTO temp.x_ref_rubrique SELECT code AS code_original, code AS code, texte AS texte, null::text AS texte_court, -1 AS rang_edition, true AS p_cumul, false AS p_detail, false AS p_nombre, 0 AS s_nombre, 1 AS c_nombre, false AS p_base, 1 AS s_base, 1 AS c_base, false AS p_heures_contrat, 0 AS s_heures_contrat, 1 AS c_heures_contrat, false AS p_heures_payees, 0 AS s_heures_payees, 1 AS c_heures_payees, false AS p_heures_travaillees, 0 AS s_heures_travaillees, 1 AS c_heures_travaillees, false AS p_masse_salariale, 3 AS s_masse_salariale, -1 AS c_masse_salariale, false AS p_brut, 3 AS s_brut, 1 AS c_brut, false AS p_avantage_nature, 3 AS s_avantage_nature, 1 AS c_avantage_nature, false AS p_frais_imposables, 3 AS s_frais_imposables, 1 AS c_frais_imposables, false AS p_cotisation_salarie, 3 AS s_cotisation_salarie, 1 AS c_cotisation_salarie, false AS p_cotisation_patronale, 5 AS s_cotisation_patronale, -1 AS c_cotisation_patronale, false AS p_od_net_salarie, 3 AS s_od_net_salarie, 1 AS c_od_net_salarie, false AS p_od_net_patronale, 5 AS s_od_net_patronale, 1 AS c_od_net_patronale, false AS p_net_imposable, 3 AS s_net_imposable, 1 AS c_net_imposable, false AS p_net_a_payer, 3 AS s_net_a_payer, 1 AS c_net_a_payer FROM rub_cum_0 ; DROP TABLE IF EXISTS w_rub_cpt; CREATE TEMP TABLE w_rub_cpt AS SELECT COD_0, (MAX(ARRAY[to_char(LIG_0,'FM000000000'),ACC_0]))[2] AS cpt_code_original FROM prod_sagex3rhp.RUBGAC WHERE COA_0 = 'FRA' AND (ACC_0 LIKE '6%' OR ACC_0 LIKE '7%') AND ACC_0 <> '' GROUP BY 1 ORDER BY 1 ; INSERT INTO w_rub_cpt SELECT w_RUBRIQUE.COD_0, w_rub_cpt_cum.cpt_code_original FROM w_RUBRIQUE JOIN w_rub_cpt w_rub_cpt_cum ON w_rub_cpt_cum.COD_0 = 'BRUT' LEFT JOIN w_rub_cpt ON w_rub_cpt.COD_0 = w_RUBRIQUE.COD_0 WHERE 'TOTBRUT' = ANY(CUM_x) AND w_rub_cpt IS NULL AND w_rub_cpt_cum.cpt_code_original <> '' ; INSERT INTO w_rub_cpt SELECT w_RUBRIQUE.COD_0, w_rub_cpt_cum.cpt_code_original FROM w_RUBRIQUE JOIN w_rub_cpt w_rub_cpt_cum ON w_rub_cpt_cum.COD_0 = 'CHARGES' LEFT JOIN w_rub_cpt ON w_rub_cpt.COD_0 = w_RUBRIQUE.COD_0 WHERE 'TOTCHARGE' = ANY(CUM_x) AND w_rub_cpt IS NULL AND w_rub_cpt_cum.cpt_code_original <> '' ; INSERT INTO w_rub_cpt SELECT w_RUBRIQUE.COD_0, w_rub_cpt_cum.cpt_code_original FROM w_RUBRIQUE JOIN w_rub_cpt w_rub_cpt_cum ON w_rub_cpt_cum.COD_0 = 'RETENUES' LEFT JOIN w_rub_cpt ON w_rub_cpt.COD_0 = w_RUBRIQUE.COD_0 WHERE 'TOTRETENU' = ANY(CUM_x) AND w_rub_cpt IS NULL AND w_rub_cpt_cum.cpt_code_original <> '' ; ANALYSE w_rub_cpt ; ]]> = date_demarrage GROUP BY 1 ; ANALYSE w_HISTOPAYE_CTRNUM ; -- Création d'une table des contrats filtrés sur la bonne entreprise. DROP TABLE IF EXISTS w_cnt ; CREATE TEMP TABLE w_cnt AS SELECT 0::numeric AS rang, null::text AS numero_contrat, CTRNUM_0, NUMLIG_0, REFNUM_0||CTRNUM_0||'-'||numlig_0 AS cnt, LEGCPY_0 || '-' || REFNUM_0||CTRNUM_0||'-'||numlig_0 AS contrat_code_original, LEGCPY_0 AS entreprise_code_original, ETRFCY_0 AS etablissement_code, LEGCPY_0 || '-' || ETRFCY_0 AS etablissement_code_original, REFNUM_0 AS mat, REFNUM_0, CTRDAT_0::date AS date_debut_contrat, CASE WHEN XITDAT_0::date = '1753-01-01'::date THEN '2099-12-31'::date ELSE XITDAT_0::date END AS date_fin_contrat, 0 AS duree, to_char(CTRDAT_0, 'YYYYMM')::int AS mois_debut, CTRGRD_0 AS motif_debut_code_original, XITGRD_0 AS motif_fin_code_original, MATREMP_0 AS mat_remplace, NATCON_0 AS type_contrat_code_original, LEGCPY_0 || '-' || REFNUM_0 AS salarie_code_original, LEGCPY_0 || '-' || matrEMP_0 AS salarie_rmp_code_original, hrs_0, -- Permettra surement de calculer le taux d'absentéisme. hrswek_0, HRSMTH_0, CASE WHEN round(HRSMTH_0/151.67,2) = 1 THEN 'TC' ELSE 'TP'||lpad((round(HRSMTH_0/151.67, 2) * 100)::int, 2, '0') END AS type_temps_travail_code_original, modtps_0, cddgrd_0 AS motif_remplacement_code_original, -- motif de remplacement (prod_sagex3rhp.ATEXTRA avec IDENT1_0 = 356) ETRSRV_0 AS service_code_original, qlf_0, -- mal renseigné. catfrt_0, CTRCODSEE_0 AS categorie_socio_professionnelle_code_original, -- CSP JOB_0 AS qualification_code_original, CATCSP_0, -- qualification code pour CMC (texte pris dans une autre table) substr(md5(job_0), 1, 5) AS job_cod_0, -- qualification code pour MOUGIN job_0 AS qualif_texte, -- qualification texte pour MOUGIN ''::text AS qualif_code, STACAT_0 AS statut_code_original, CATJOB_0 AS code_emploi_code_original, '' AS grille_groupe_y, -- mode grille y. '' AS grille_groupe_x, -- ON ne prend pas l'échelon. ''::text AS grille_groupe, '' AS grille_y, '' AS grille_x, ''::text AS grille, MAX(datlib_0) OVER (PARTITION BY REFNUM_0) AS datlib_0, MAX(datanc_0) OVER (PARTITION BY REFNUM_0) AS datanc_0, null::boolean AS acc_anc, -- accumuler ou non de l'ancienneté (1 ou 0). pot_0, -- Ne pas utiliser '' AS type_horaire_ori FROM prod_sagex3rhp.EMPLOCTR JOIN w_periode ON 1=1 JOIN prod_sagex3rhp.FACILITY ON FACILITY.fcy_0 = EMPLOCTR.ETRFCY_0 JOIN prod_sagex3rhp.COMPANY ON FACILITY.LEGCPY_0 = COMPANY.CPY_0 WHERE 1=1 AND COMPANY.CRN_0 IN (SELECT substr(rhp_in('siren'), 1, 9)) AND ( XITDAT_0::date = '1753-01-01' OR XITDAT_0 >= date_demarrage OR CTRNUM_0 IN (SELECT CTRNUM_0_paye FROM w_HISTOPAYE_CTRNUM) ) order by REFNUM_0, CTRDAT_0 ; ANALYSE w_cnt ; -- Mise à jour de la durée des contrats. UPDATE w_cnt SET duree = (CASE WHEN date_fin_contrat = '2099-12-31'::date THEN current_date ELSE date_fin_contrat END) - date_debut_contrat + 1 ; -- Détermination du mode de grille. DROP TABLE IF EXISTS w_gri ; CREATE TEMP TABLE w_gri AS SELECT count(distinct grille_groupe_y) < count(distinct grille_groupe_x) AS x_mode FROM w_cnt ; UPDATE w_cnt SET grille_groupe = (CASE WHEN x_mode THEN grille_groupe_x ELSE grille_groupe_y END), grille = (CASE WHEN x_mode THEN grille_x ELSE grille_y END), acc_anc = date_fin_contrat > (CASE WHEN x_mode THEN datanc_0 ELSE datlib_0 END), -- ON cumule de l'ancienneté uniquement lorsque le contrat dépasse la date d'ancienneté. qualif_code = (CASE WHEN x_mode THEN job_cod_0 ELSE catcsp_0 END) FROM w_gri ; DROP SEQUENCE IF EXISTS s_cnt; CREATE TEMP SEQUENCE s_cnt START 1 ; UPDATE w_cnt SET rang = nextval('s_cnt') ; -- #correction Attention, les contrats sont à aggréger. -- Identification des ruptures de contrat. update w_cnt set numero_contrat = subq.numero_contrat FROM ( select CASE WHEN t2.motif_fin_code_original = t1.motif_debut_code_original AND (t2.date_fin_contrat + '1 day'::interval)::date = t1.date_debut_contrat THEN null ELSE t1.cnt END AS numero_contrat, t1.cnt, t1.mat FROM w_cnt AS t1 left join w_cnt AS t2 ON 1=1 AND t2.mat = t1.mat AND t2.rang + 1 = t1.rang) AS subq WHERE 1=1 AND w_cnt.mat = subq.mat AND w_cnt.cnt = subq.cnt AND w_cnt.numero_contrat is distinct FROM subq.numero_contrat ; -- #correction Attention, les contrats sont à aggréger. -- Etalement des ruptures sur les contrats correspondant à l'évolution de carrière d'un salarié. update w_cnt set numero_contrat = subq.numero_contrat FROM ( select t1.cnt, t1.mat, (MAX(ARRAY[lpad(t2.rang, 4, '0'), t2.numero_contrat]))[2] AS numero_contrat FROM w_cnt AS t1 left join w_cnt AS t2 ON 1=1 AND t2.mat = t1.mat AND t2.rang < t1.rang WHERE 1=1 AND t1.numero_contrat is null AND t2.numero_contrat is not null GROUP BY 1,2 ) AS subq WHERE 1=1 AND w_cnt.mat = subq.mat AND w_cnt.cnt = subq.cnt AND w_cnt.numero_contrat is distinct FROM subq.numero_contrat ; -- Association contrat au bulletin (on se débrouille !!!) DROP TABLE IF EXISTS w_EMPLOCTR; CREATE TEMP TABLE w_EMPLOCTR AS SELECT CTRNUM_0, CASE WHEN count(*) = 1 THEN MAX(LEGCPY_0 || '-' || REFNUM_0||CTRNUM_0||'-'||NUMLIG_0) ELSE NULL END AS contrat_code_original FROM prod_sagex3rhp.EMPLOCTR JOIN prod_sagex3rhp.FACILITY ON FACILITY.FCY_0 = EMPLOCTR.ETRFCY_0 JOIN prod_sagex3rhp.COMPANY ON FACILITY.LEGCPY_0 = COMPANY.CPY_0 WHERE 1=1 AND COMPANY.CRN_0 IN (SELECT substr(rhp_in('siren'), 1, 9)) GROUP BY 1 ; ANALYSE w_EMPLOCTR ; DROP TABLE IF EXISTS w_EMPLOCTR_mois; CREATE TEMP TABLE w_EMPLOCTR_mois AS SELECT CTRNUM_0, p_calendrier_mois.date_debut AS date_debut_mois, CASE WHEN count(*) = 1 THEN MAX(LEGCPY_0 || '-' || REFNUM_0||CTRNUM_0||'-'||NUMLIG_0) ELSE NULL END AS contrat_code_original FROM prod_sagex3rhp.EMPLOCTR JOIN prod_sagex3rhp.FACILITY ON FACILITY.FCY_0 = EMPLOCTR.ETRFCY_0 JOIN prod_sagex3rhp.COMPANY ON FACILITY.LEGCPY_0 = COMPANY.CPY_0 JOIN base.p_calendrier_mois ON p_calendrier_mois.date_debut <= now() AND date(CTRDAT_0) <= p_calendrier_mois.date_fin AND ( date(XITDAT_0) >= p_calendrier_mois.date_debut OR date(XITDAT_0) < '19000101' ) WHERE 1=1 AND COMPANY.CRN_0 IN (SELECT substr(rhp_in('siren'), 1, 9)) GROUP BY 1,2 HAVING count(*) = 1 ; ANALYSE w_EMPLOCTR_mois ; DROP TABLE IF EXISTS w_HRDSNDMT; CREATE TEMP TABLE w_HRDSNDMT AS SELECT BUL_0, MAX(CTRNUM_0) AS CTRNUM_0, MAX(STRDAT_0) AS STRDAT_0, MAX(CTRDAT_0) AS CTRDAT_0, NULL::text AS contrat_code_original FROM prod_sagex3rhp.HRDSNDMC JOIN prod_sagex3rhp.HRDSNDMT ON HRDSNDMC.DSNCTRUID_0 = HRDSNDMT.DSNCTRUID_0 GROUP BY 1 ; UPDATE w_HRDSNDMT SET contrat_code_original = LEGCPY_0 || '-' || REFNUM_0||EMPLOCTR.CTRNUM_0||'-'||NUMLIG_0 FROM prod_sagex3rhp.EMPLOCTR JOIN prod_sagex3rhp.FACILITY ON FACILITY.FCY_0 = EMPLOCTR.ETRFCY_0 WHERE EMPLOCTR.CTRNUM_0 = w_HRDSNDMT.CTRNUM_0 AND EMPLOCTR.CTRDAT_0 = w_HRDSNDMT.CTRDAT_0 ; UPDATE w_HRDSNDMT SET contrat_code_original = LEGCPY_0 || '-' || REFNUM_0||EMPLOCTR.CTRNUM_0||'-'||NUMLIG_0 FROM prod_sagex3rhp.EMPLOCTR JOIN prod_sagex3rhp.FACILITY ON FACILITY.FCY_0 = EMPLOCTR.ETRFCY_0 WHERE EMPLOCTR.CTRNUM_0 = w_HRDSNDMT.CTRNUM_0 AND contrat_code_original IS NULL AND EMPLOCTR.CTRDAT_0 = w_HRDSNDMT.STRDAT_0 ; UPDATE w_HRDSNDMT SET contrat_code_original = LEGCPY_0 || '-' || REFNUM_0||EMPLOCTR.CTRNUM_0||'-'||NUMLIG_0 FROM prod_sagex3rhp.EMPLOCTR JOIN prod_sagex3rhp.FACILITY ON FACILITY.FCY_0 = EMPLOCTR.ETRFCY_0 WHERE EMPLOCTR.CTRNUM_0 = w_HRDSNDMT.CTRNUM_0 AND contrat_code_original IS NULL AND date_trunc('month',EMPLOCTR.CTRDAT_0) = date_trunc('month',w_HRDSNDMT.CTRDAT_0) ; UPDATE w_HRDSNDMT SET contrat_code_original = LEGCPY_0 || '-' || REFNUM_0||EMPLOCTR.CTRNUM_0||'-'||NUMLIG_0 FROM prod_sagex3rhp.EMPLOCTR JOIN prod_sagex3rhp.FACILITY ON FACILITY.FCY_0 = EMPLOCTR.ETRFCY_0 WHERE EMPLOCTR.CTRNUM_0 = w_HRDSNDMT.CTRNUM_0 AND contrat_code_original IS NULL AND date_trunc('month',EMPLOCTR.CTRDAT_0) = date_trunc('month',w_HRDSNDMT.STRDAT_0) ; UPDATE w_HRDSNDMT SET contrat_code_original = LEGCPY_0 || '-' || REFNUM_0||EMPLOCTR.CTRNUM_0||'-'||NUMLIG_0 FROM prod_sagex3rhp.EMPLOCTR JOIN prod_sagex3rhp.FACILITY ON FACILITY.FCY_0 = EMPLOCTR.ETRFCY_0 WHERE EMPLOCTR.CTRNUM_0 = w_HRDSNDMT.CTRNUM_0 AND contrat_code_original IS NULL AND w_HRDSNDMT.STRDAT_0 BETWEEN EMPLOCTR.CTRDAT_0 AND EMPLOCTR.XITDAT_0 ; UPDATE w_HRDSNDMT SET contrat_code_original = LEGCPY_0 || '-' || REFNUM_0||EMPLOCTR.CTRNUM_0||'-'||NUMLIG_0 FROM prod_sagex3rhp.EMPLOCTR JOIN prod_sagex3rhp.FACILITY ON FACILITY.FCY_0 = EMPLOCTR.ETRFCY_0 WHERE EMPLOCTR.CTRNUM_0 = w_HRDSNDMT.CTRNUM_0 AND contrat_code_original IS NULL AND w_HRDSNDMT.STRDAT_0 >= EMPLOCTR.CTRDAT_0 AND EMPLOCTR.XITDAT_0 < '19000101' ; DROP TABLE IF EXISTS w_bulletin_contrat; CREATE TEMP TABLE w_bulletin_contrat AS SELECT BUL_0, EMP_0, CTRNUM_0, DAT_0, row_number() OVER(PARTITION BY EMP_0, CTRNUM_0, DAT_0 ORDER BY BUL_0) AS seq, contrat_code_original FROM ( SELECT HISTOPAYE.BUL_0, MAX(HISTOPAYE.EMP_0) AS EMP_0, MAX(HISTOPAYE.CTRNUM_0) AS CTRNUM_0, date(MAX(date_trunc('month',HISTOPAYE.DAT_0))) AS DAT_0, MAX(COALESCE(w_EMPLOCTR_mois.contrat_code_original,w_EMPLOCTR.contrat_code_original,w_HRDSNDMT.contrat_code_original)) AS contrat_code_original FROM prod_sagex3rhp.HISTOPAYE JOIN w_EMPLOCTR ON HISTOPAYE.CTRNUM_0 = w_EMPLOCTR.CTRNUM_0 LEFT JOIN w_EMPLOCTR_mois ON HISTOPAYE.CTRNUM_0 = w_EMPLOCTR_mois.CTRNUM_0 AND date(date_trunc('month',HISTOPAYE.DAT_0)) = date_debut_mois LEFT JOIN w_HRDSNDMT ON HISTOPAYE.BUL_0 = w_HRDSNDMT.BUL_0 GROUP BY 1 ) subview ; ANALYSE w_bulletin_contrat ; SELECT base.cti_execute( 'UPDATE w_bulletin_contrat SET contrat_code_original = subview.contrat_code_original_precedent FROM ( SELECT BUL_0, contrat_code_original, LAG(contrat_code_original) OVER (PARTITION BY CTRNUM_0 ORDER BY DAT_0) AS contrat_code_original_precedent FROM w_bulletin_contrat ) subview WHERE w_bulletin_contrat.BUL_0 = subview.BUL_0 AND w_bulletin_contrat.contrat_code_original IS NULL AND contrat_code_original_precedent IS NOT NULL ',100) ; SELECT base.cti_execute( 'UPDATE w_bulletin_contrat SET contrat_code_original = subview.contrat_code_original_suivant FROM ( SELECT BUL_0, contrat_code_original, LEAD(contrat_code_original) OVER (PARTITION BY CTRNUM_0 ORDER BY DAT_0) AS contrat_code_original_suivant FROM w_bulletin_contrat ) subview WHERE w_bulletin_contrat.BUL_0 = subview.BUL_0 AND w_bulletin_contrat.contrat_code_original IS NULL AND contrat_code_original_suivant IS NOT NULL ',100) ; -- Création d'une table de la paie filtrée sur la bonne entreprise. DROP TABLE IF EXISTS w_HISTOPAYE ; CREATE TEMP TABLE w_HISTOPAYE AS SELECT HISTOPAYE.rowid, MAX(HISTOPAYE.EMP_0) AS mat, MAX(w_cnt.entreprise_code_original) AS entreprise_code_original, MAX(w_cnt.etablissement_code) AS etablissement_code, MAX(w_cnt.etablissement_code_original) AS etablissement_code_original, MAX(w_cnt.salarie_code_original) AS salarie_code_original, MAX(w_cnt.contrat_code_original) AS contrat_code_original, MAX(HISTOPAYE.BUL_0) AS bulletin_code_original, MAX(HISTOPAYE.DAT_0::date) AS date_paie, MAX(HISTOPAYE.DAT_0::date) AS date_ligne, MAX(HISTOPAYE.BUL_0) AS BUL_0, MAX(HISTOPAYE.EMP_0) AS EMP_0, MAX(HISTOPAYE.DAT_0) AS DAT_0, MAX(HISTOPAYE.ROW_0::bigint) AS ROW_0, MAX(HISTOPAYE.RUB_0) AS RUB_0, MAX(HISTOPAYE.TYP_0) AS TYP_0, MAX(HISTOPAYE.BAS_0) AS BAS_0, MAX(HISTOPAYE.RAT_0) AS RAT_0, MAX(HISTOPAYE.AMT_0) AS AMT_0, COALESCE(MAX(CASE WHEN HISTOPAYE.RUB_0 <> 'CHARGES' AND HISTOPAYE.TYP_0 IN (1,7) THEN RAT_0 ELSE NULL END),0) AS RAT_0_1, COALESCE(MAX(CASE WHEN HISTOPAYE.RUB_0 <> 'CHARGES' AND HISTOPAYE.TYP_0 IN (1,7) THEN AMT_0 ELSE NULL END),0) AS AMT_0_1, COALESCE(MAX(CASE WHEN HISTOPAYE.RUB_0 = 'CHARGES' OR HISTOPAYE.TYP_0 IN (2,8) THEN RAT_0 ELSE NULL END),0) AS RAT_0_2, COALESCE(MAX(CASE WHEN HISTOPAYE.RUB_0 = 'CHARGES' OR HISTOPAYE.TYP_0 IN (2,8) THEN AMT_0 ELSE NULL END),0) AS AMT_0_2, MAX(HISTOPAYE.CTRNUM_0) AS CTRNUM_0AMTPRN_0, MAX(AMTPRN_0) AS AMTPRN_0 FROM prod_sagex3rhp.HISTOPAYE JOIN w_bulletin_contrat ON HISTOPAYE.BUL_0 = w_bulletin_contrat.BUL_0 JOIN prod_sagex3rhp.RUBRIQUE ON RUB_0 = RUBRIQUE.COD_0 JOIN w_cnt ON w_bulletin_contrat.contrat_code_original = w_cnt.contrat_code_original JOIN w_periode ON 1=1 WHERE 1=1 AND (1!=1 OR HISTOPAYE.BAS_0 != 0 OR HISTOPAYE.RAT_0 != 0 OR HISTOPAYE.AMT_0 != 0) AND HISTOPAYE.DAT_0 >= date_demarrage GROUP BY 1 ; -- #correction des dates de ligne de bulletin : des fois, dates différentes pour un même bulletin. UPDATE w_HISTOPAYE SET date_paie = subq.DAT_0, DAT_0 = subq.DAT_0 FROM ( SELECT BUL_0, DAT_0 FROM w_HISTOPAYE WHERE RUB_0 = 'BRUT') AS subq WHERE 1=1 AND w_HISTOPAYE.BUL_0 = subq.BUL_0 AND w_HISTOPAYE.DAT_0 != subq.DAT_0 ; -- Création d'une table par bulletin avec date de début/fin. DROP TABLE IF EXISTS w_bul ; CREATE TEMP TABLE w_bul AS SELECT BUL_0, MAX(bulletin_code_original) AS bulletin_code_original, MAX(mat) AS mat, MAX(entreprise_code_original) AS entreprise_code_original, MAX(etablissement_code) AS etablissement_code, MAX(etablissement_code_original) AS etablissement_code_original, MAX(salarie_code_original) AS salarie_code_original, MAX(contrat_code_original) AS contrat_code_original, MAX(date_paie) AS date_paie, MAX(date_ligne) AS date_fin_bulletin, date(date_trunc('month',MIN(date_ligne))) AS date_debut_bulletin, MAX(to_char(date_paie, 'YYYYMM')::int) AS mois_paie, (MAX(to_char(date_paie, 'YYYYMM')) || lpad((sum(CASE WHEN RUB_0 = 'NBJC_SALE' THEN @BAS_0 ELSE 0 END) + 1)::int, 2, '0'))::date AS date_paie_debut, -- reconstitution à partir d'une rubrique de la date de début de contrat associé au bulletin. Surprenant !!! null::date AS date_paie_fin, null::text AS cnt, MAX(CASE WHEN RUB_0 = 'COEF_BULL' THEN @BAS_0 ELSE 0 END)::int::text AS coeff -- utile lorsque le coefficient du contrat n'est pas fiable (x_mode à true). FROM w_HISTOPAYE GROUP BY 1 ; -- #correction de la date de début de paie lorsqu'elle est postérieure à la date de paie UPDATE w_bul SET date_paie_debut = date_paie WHERE date_paie < date_paie_debut ; -- Mise à jour de la date de fin et du contrat associé aux bulletins. UPDATE w_bul SET date_paie_fin = least(w_cnt.date_fin_contrat, (date_trunc('MONTH', w_bul.date_paie_debut) + '1 month - 1 day'::interval)::date), cnt = w_cnt.cnt FROM w_cnt WHERE 1=1 AND w_cnt.mat = w_bul.mat AND w_cnt.date_debut_contrat = w_bul.date_paie_debut ; -- Mise à jour de la date de fin et du contrat associé aux bulletins (pour les contrats couvrants plusieurs mois). UPDATE w_bul SET date_paie_fin = least(w_cnt.date_fin_contrat, (date_trunc('MONTH', w_bul.date_paie_debut) + '1 month - 1 day'::interval)::date), cnt = w_cnt.cnt FROM w_cnt WHERE 1=1 AND w_cnt.mat = w_bul.mat AND w_bul.date_paie_debut between w_cnt.date_debut_contrat AND w_cnt.date_fin_contrat AND w_bul.date_paie_fin IS NULL ; -- Association des bulletins hors période de contrat (au contrat le plus en amont). UPDATE w_bul SET date_paie_fin = date_paie_debut, -- ON fait une paie d'un jour cnt = subq.cnt FROM ( select w_bul.mat, BUL_0, (MAX(ARRAY[w_cnt.date_fin_contrat::text, w_cnt.cnt]))[2] AS cnt FROM w_bul join w_cnt ON w_cnt.mat = w_bul.mat WHERE 1=1 AND w_cnt.date_fin_contrat < w_bul.date_paie_debut AND w_bul.date_paie_fin IS NULL GROUP BY 1, 2) AS subq WHERE 1=1 AND w_bul.mat = subq.mat AND w_bul.BUL_0 = subq.BUL_0 AND w_bul.date_paie_fin IS NULL ; -- Correction des ventilations. DROP TABLE IF EXISTS w_ven ; CREATE TEMP TABLE w_ven AS SELECT EMP_0, BUL_0, cce_0, cce_1, sum(coe_0)::numeric AS coe_0 FROM prod_sagex3rhp.valana GROUP BY 1,2,3,4 ; UPDATE w_ven SET coe_0 = 100 WHERE coe_0 = 0 ; DROP TABLE IF EXISTS temp.x_ref_salarie ; CREATE TABLE temp.x_ref_salarie AS SELECT EMPLOID.REFNUM_0 AS matricule, EMPLOID.REFNUM_0 AS code, entreprise_code_original || '-' || EMPLOID.REFNUM_0 AS code_original, MAX(NUMSSC_0) AS nir, MAX(entreprise_code_original) AS entreprise, MAX(NAM_0) AS nom, MAX(OLDNAM_0) AS nom_naissance, MAX(SRN_0) AS prenom, COALESCE(MAX(DATBRN_0)::date, '1962-04-18'::date) AS date_naissance, MAX(CASE WHEN SEX_0 = 1 THEN 'M' ELSE 'F' END) AS sexe, MAX(EMPLOID.NTT_0) AS nationalite, MAX(EMPLOID.CODPOS_0) AS code_postal, MAX(EMPLOID.SITFAM_0) AS situation_famille, MAX(w_cnt.date_debut_contrat) AS date_debut, MAX(w_cnt.date_fin_contrat) AS date_fin, MIN(w_cnt.date_debut_contrat) AS date_entree_ets, MAX(w_cnt.date_fin_contrat) AS date_sortie_ets, MIN(w_cnt.date_debut_contrat) AS date_anciennete, MAX(ADD1_0) AS adresse1, MAX(ADD2_0) AS adresse2, -- Champs dédiés au public. null::date AS date_entree_fp, null::date AS date_entree_fph, 0 AS no_adeli, 0 AS code_cotisation_id, 0 AS matricule_retraite FROM prod_sagex3rhp.emploid JOIN w_cnt ON w_cnt.mat = emploid.REFNUM_0 GROUP BY 1,2,3 ; DROP TABLE IF EXISTS temp.x_hst_contrat ; CREATE TABLE temp.x_hst_contrat AS SELECT contrat_code_original AS cnt_code_original, MAX(entreprise_code_original) AS ent_code_original, MAX(etablissement_code) AS ets_code_original, MAX(etablissement_code_original) AS ety_code_original, MAX(salarie_code_original) AS sal_code_original, MAX(w_cnt.numero_contrat) AS numero_contrat, --cnt_uid, -- contrat universal id. MIN(date_debut_contrat) AS date_debut, MAX(date_fin_contrat) AS date_fin, row_number() over () AS row_id FROM w_cnt GROUP BY 1 ; -- HISTORIQUE DES BULLETINS. DROP TABLE IF EXISTS temp.x_hst_bulletin ; CREATE TABLE temp.x_hst_bulletin AS SELECT entreprise_code_original AS ent_code_original, etablissement_code AS ets_code_original, etablissement_code_original AS ety_code_original, salarie_code_original AS sal_code_original, contrat_code_original AS cnt_code_original, bulletin_code_original AS bul_code_original, date_debut_bulletin AS date_debut, date_fin_bulletin AS date_fin, date_paie, mois_paie, row_number() over () AS row_id, row_number() over (order by etablissement_code_original, salarie_code_original, bulletin_code_original) AS bul_id, 0 AS est_hors_periode FROM w_bul ; DELETE FROM temp.x_hst_bulletin WHERE cnt_code_original is null ; UPDATE temp.x_hst_bulletin SET est_hors_periode = '1' FROM temp.x_hst_contrat WHERE x_hst_bulletin.cnt_code_original = x_hst_contrat.cnt_code_original AND x_hst_bulletin.date_debut > x_hst_contrat.date_fin ; -- ICI : Tous les bulletins doivent avoir un contrat de renseigné. -- A remonter plus tard dans une table spéciale avant suppression pour controle expert. DELETE FROM temp.x_hst_bulletin WHERE cnt_code_original is null ; -- La date min du premier contrat et/ou du premier bulletin détermine le début de la ventilation du salarié. DROP TABLE IF EXISTS w_lim_sal ; CREATE TEMP TABLE w_lim_sal AS WITH toto AS ( SELECT sal_code_original, min(date_debut) AS date_debut, max(case when date_fin = '2099-12-31'::date then base.cti_last_day(current_date) else date_fin end) AS date_fin FROM temp.x_hst_contrat GROUP BY 1 UNION ALL SELECT sal_code_original, min(date_debut) AS date_debut, max(case when date_fin = '2099-12-31'::date then base.cti_last_day(current_date) else date_fin end) AS date_fin FROM temp.x_hst_bulletin GROUP BY 1 ) SELECT sal_code_original, min(date_debut) AS date_debut, to_char(min(date_debut), 'YYYYMM')::int AS mois_debut, max(date_fin) AS date_fin, to_char(max(date_fin), 'YYYYMM')::int AS mois_fin FROM toto GROUP BY 1 ; -- HISTORIQUE ETP Théorique contrat. DROP TABLE IF EXISTS temp.x_hst_contrat_proprietes ; CREATE TABLE temp.x_hst_contrat_proprietes AS SELECT w_cnt.etablissement_code_original AS ety_code_original, w_cnt.salarie_code_original AS sal_code_original, w_cnt.contrat_code_original AS cnt_code_original, GREATEST(w_cnt.date_debut_contrat, w_lim_sal.date_debut) AS date_effet, round(HRSMTH_0/151.67, 2) AS 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, code_emploi_code_original FROM w_cnt JOIN w_lim_sal ON w_lim_sal.sal_code_original = w_cnt.salarie_code_original ; ANALYSE temp.x_hst_contrat_proprietes ; -- Suppression des proprietes pour des contrats dont la periode est comprise dans un autre contrat DELETE FROM temp.x_hst_contrat_proprietes WHERE cnt_code_original IN ( SELECT w_cnt.contrat_code_original FROM w_cnt JOIN w_cnt w_cnt2 ON w_cnt.salarie_code_original = w_cnt2.salarie_code_original AND w_cnt.date_debut_contrat >= w_cnt2.date_debut_contrat AND w_cnt.date_fin_contrat < w_cnt2.date_fin_contrat AND w_cnt.rang <> w_cnt2.rang ) ; DROP TABLE IF EXISTS temp.x_hst_etp_contrat ; CREATE TABLE temp.x_hst_etp_contrat AS SELECT ety_code_original, sal_code_original, cnt_code_original, date_effet, etp_contrat FROM temp.x_hst_contrat_proprietes ; DROP TABLE IF EXISTS temp.x_hst_categorie_socio_professionnelle ; CREATE TABLE temp.x_hst_categorie_socio_professionnelle AS SELECT ety_code_original, sal_code_original, cnt_code_original, date_effet, categorie_socio_professionnelle_code_original FROM temp.x_hst_contrat_proprietes ; DROP TABLE IF EXISTS temp.x_hst_motif_debut_contrat ; CREATE TABLE temp.x_hst_motif_debut_contrat AS SELECT ety_code_original, sal_code_original, cnt_code_original, date_effet, motif_debut_code_original FROM temp.x_hst_contrat_proprietes ; DROP TABLE IF EXISTS temp.x_hst_motif_fin_contrat ; CREATE TABLE temp.x_hst_motif_fin_contrat AS SELECT ety_code_original, sal_code_original, cnt_code_original, date_effet, motif_fin_code_original FROM temp.x_hst_contrat_proprietes ; DROP TABLE IF EXISTS temp.x_hst_type_contrat ; CREATE TABLE temp.x_hst_type_contrat AS SELECT ety_code_original, sal_code_original, cnt_code_original, date_effet, type_contrat_code_original FROM temp.x_hst_contrat_proprietes ; DROP TABLE IF EXISTS temp.x_hst_qualification ; CREATE TABLE temp.x_hst_qualification AS SELECT ety_code_original, sal_code_original, cnt_code_original, date_effet, qualification_code_original FROM temp.x_hst_contrat_proprietes ; DROP TABLE IF EXISTS temp.x_hst_statut ; CREATE TABLE temp.x_hst_statut AS SELECT ety_code_original, sal_code_original, cnt_code_original, date_effet, statut_code_original FROM temp.x_hst_contrat_proprietes ; DROP TABLE IF EXISTS temp.x_hst_type_temps_travail ; CREATE TABLE temp.x_hst_type_temps_travail AS SELECT ety_code_original, sal_code_original, cnt_code_original, date_effet, type_temps_travail_code_original FROM temp.x_hst_contrat_proprietes ; DROP TABLE IF EXISTS temp.x_hst_service ; CREATE TABLE temp.x_hst_service AS SELECT ety_code_original, sal_code_original, cnt_code_original, date_effet, service_code_original FROM temp.x_hst_contrat_proprietes ; DROP TABLE IF EXISTS temp.x_hst_code_emploi ; CREATE TABLE temp.x_hst_code_emploi AS SELECT ety_code_original, sal_code_original, cnt_code_original, date_effet, code_emploi_code_original FROM temp.x_hst_contrat_proprietes ; DROP TABLE IF EXISTS temp.x_hst_grille ; CREATE TABLE temp.x_hst_grille 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 grille_code_original limit 0 ; ]]> = mois_demarrage AND w_HISTOPAYE.TYP_0 IN (1,2,7,8) AND ( w_RUBRIQUE.AMTPRN_0 BETWEEN 2 AND 5 OR 'TOTNAP' = ANY(CUM_x) OR w_HISTOPAYE.RUB_0 = 'HRES_EFF' OR w_HISTOPAYE.RUB_0 = 'HRES_PAY' OR w_HISTOPAYE.RUB_0 = 'HRES_SAL' OR w_HISTOPAYE.RUB_0 = 'NET_IMPOS' OR w_HISTOPAYE.RUB_0 = 'NET_PAYER' OR w_HISTOPAYE.RUB_0 = 'BRUT' OR w_HISTOPAYE.RUB_0 = 'CHARGES' OR w_HISTOPAYE.RUB_0 = 'RETENUES' OR w_HISTOPAYE.RUB_0 = 'RETENUES' OR w_HISTOPAYE.RUB_0 = ANY(SELECT code_original FROM rh.t_rubriques WHERE user_modified) ) AND (1!=1 OR w_HISTOPAYE.AMT_0 != 0 OR w_HISTOPAYE.BAS_0 != 0) ; ]]>