You can not select more than 25 topics Topics must start with a letter or number, can include dashes ('-') and can be up to 35 characters long.
 
 
 

1285 lines
40 KiB

<?xml version="1.0" encoding="ISO-8859-15"?>
<ROOT>
<NODE name="INIT" label="SPECIFIQUE CEGIDHRU">
<NODE label="Identification des entreprises/établissements">
<sqlcmd><![CDATA[
-- Entreprises choisies
DROP TABLE IF EXISTS w_entreprise
;
CREATE TEMP TABLE w_entreprise AS
SELECT rhp('siren') AS in_entreprise
;
ANALYSE w_entreprise
;
-- Préparation table contrats
DROP TABLE IF EXISTS w_ETL009;
CREATE TEMP TABLE w_ETL009 AS
SELECT *,
row_number() OVER(PARTITION BY ID_INDIVIDU ORDER BY DATE_EFFET_CTR, CODE_ETS) AS NUMERO_CONTRAT,
DATE_EFFET_CTR AS DATE_ENTREE,
'20991231'::date AS DATE_FIN_CONT,
'20991231'::date AS DATE_DEPART,
''::text AS MOTIF_EMBAUCHE,
''::text AS DEPART_CAUSE,
CODE_ETS AS ent_code_original,
'1'::text AS ets_code_original,
CODE_ETS||'-'||'1' AS ety_code_original,
ID_INDIVIDU::text AS sal_code_original,
ID_INDIVIDU::text || '-' || row_number() OVER(PARTITION BY ID_INDIVIDU ORDER BY DATE_EFFET_CTR, CODE_ETS) AS cnt_code_original
FROM prod_cegidhru.ETL009
;
ANALYSE w_ETL009
;
DELETE FROM w_ETL009
WHERE CODE_ETS NOT IN (SELECT in_entreprise FROM w_entreprise)
;
UPDATE w_ETL009 SET
DATE_ENTREE = ETL008.DATE_ENTREE,
DATE_FIN_CONT = COALESCE(ETL008.DATE_FIN_CONT, ETL008.DATE_DEPART,'20991231'),
DATE_DEPART = ETL008.DATE_DEPART,
MOTIF_EMBAUCHE = ETL008.MOTIF_EMBAUCHE,
DEPART_CAUSE = ETL008.DEPART_CAUSE
FROM prod_cegidhru.ETL008
WHERE
ETL008.ID_INDIVIDU = w_ETL009.ID_INDIVIDU AND
ETL008.DATE_ENTREE = w_ETL009.DATE_EFFET_CTR
;
-- Trim des champs text
SELECT base.cti_execute('UPDATE w_ETL009 SET ' ||
array_to_string(base.cti_array_accum(trim_set),',') ||
' WHERE ' ||
array_to_string(base.cti_array_accum(trim_where),' OR '),1)
FROM
(
SELECT
column_name||'=trim('||column_name||')' AS trim_set,
column_name||' IS DISTINCT FROM trim('||column_name||')' AS trim_where
FROM information_schema.columns
WHERE table_name = 'w_etl009' AND
data_type = 'text'
GROUP BY 1,2
) subview
;
-- Préparation table paie (fusion historique et paie en cours)
DROP TABLE IF EXISTS w_ETL016;
CREATE TEMP TABLE w_ETL016 AS
SELECT
MATRICULE,
NUMERO_CONTRAT,
EMPLOYEUR,
NUM_SIREN_EMPL,
CODE_ETS,
ETB_SIRET_NUMER,
ETB_SIRET_NOM,
MOIS_COMPTABLE,
MOIS_PAIE,
DATE_DEB_BUL,
DATE_FIN_BUL,
NUMERO_RUB,
LIB_RUBRIQUE,
TYPE_RUBRIQUE,
INCREMENT_RUB,
INFO_COMP,
BASE,
TAUX_SALAR,
MONTANT_SALAR,
TAUX_PATRONAL,
MONT_PATRONAL,
TAUX_GLOBAL,
MONTANT_GLOBAL,
CODE_ETS AS ent_code_original,
'1'::text AS ets_code_original,
CODE_ETS||'-'||'1' AS ety_code_original,
MATRICULE::text AS sal_code_original,
MATRICULE::text || '-' || NUMERO_CONTRAT || '-' || MOIS_COMPTABLE || '-' || MOIS_PAIE AS bul_code_original
FROM prod_cegidhru.ETL016
JOIN w_entreprise ON CODE_ETS = in_entreprise
;
INSERT INTO w_ETL016
SELECT
MATRICULE,
NUMERO_CONTRAT,
EMPLOYEUR,
NUM_SIREN_EMPL,
CODE_ETS,
ETB_SIRET_NUMER,
ETB_SIRET_NOM,
MOIS_COMPTABLE,
MOIS_PAIE,
DATE_DEB_BUL,
DATE_FIN_BUL,
NUMERO_RUB,
LIB_RUBRIQUE,
TYPE_RUBRIQUE,
INCREMENT_RUB,
INFO_COMP,
BASE,
TAUX_SALAR,
MONTANT_SALAR,
TAUX_PATRONAL,
MONT_PATRONAL,
TAUX_GLOBAL,
MONTANT_GLOBAL,
CODE_ETS AS ent_code_original,
'1'::text AS ets_code_original,
CODE_ETS||'-'||'1' AS ety_code_original,
MATRICULE::text AS sal_code_original,
MATRICULE::text || '-' || NUMERO_CONTRAT || '-' || MOIS_COMPTABLE || '-' || MOIS_PAIE AS bul_code_original
FROM prod_cegidhru.ETL015
JOIN w_entreprise ON CODE_ETS = in_entreprise
;
-- Trim des champs text
SELECT base.cti_execute('UPDATE w_ETL016 SET ' ||
array_to_string(base.cti_array_accum(trim_set),',') ||
' WHERE ' ||
array_to_string(base.cti_array_accum(trim_where),' OR '),1)
FROM
(
SELECT
column_name||'=trim('||column_name||')' AS trim_set,
column_name||' IS DISTINCT FROM trim('||column_name||')' AS trim_where
FROM information_schema.columns
WHERE table_name = 'w_etl016' AND
data_type = 'text'
GROUP BY 1,2
) subview
;
ANALYSE w_ETL016
;
-- Trim des champs text de la table des paramètres
SELECT base.cti_execute('UPDATE prod_cegidhru.ETL014 SET ' ||
array_to_string(base.cti_array_accum(trim_set),',') ||
' WHERE ' ||
array_to_string(base.cti_array_accum(trim_where),' OR '),1)
FROM
(
SELECT
column_name||'=trim('||column_name||')' AS trim_set,
column_name||' IS DISTINCT FROM trim('||column_name||')' AS trim_where
FROM information_schema.columns
WHERE table_name = 'etl014' AND
data_type = 'text'
GROUP BY 1,2
) subview
;
-- Préparation table ventilation analytique
DROP TABLE IF EXISTS w_ETL010;
CREATE TEMP TABLE w_ETL010 AS
WITH ETL010 AS
(SELECT w_ETL009.ID_INDIVIDU,
w_ETL009.NUMERO_CONTRAT,
(ARRAY[
trim(COALESCE(IMPUTATION_01,IMPUTATION_ANA)),
trim(IMPUTATION_02),
trim(IMPUTATION_03),
trim(IMPUTATION_04),
trim(IMPUTATION_05),
trim(IMPUTATION_06),
trim(IMPUTATION_07),
trim(IMPUTATION_08),
trim(IMPUTATION_09),
trim(IMPUTATION_10)
]) AS IMPUTATION_array,
(ARRAY[
COALESCE(POURCENTAGE_IMP,100),
PRC02,
PRC03,
PRC04,
PRC05,
PRC06,
PRC07,
PRC08,
PRC09,
PRC10
]) AS PRC_array,
ent_code_original,
ets_code_original,
ety_code_original,
sal_code_original,
cnt_code_original
FROM w_ETL009
LEFT JOIN prod_cegidhru.ETL010 ON
ETL010.ID_INDIVIDU = w_ETL009.ID_INDIVIDU AND
ETL010.NUMERO_CONTRAT = w_ETL009.NUMERO_CONTRAT
)
SELECT ETL010.*,
IMPUTATION_array[i] AS IMPUTATION_XX,
PRC_array[i] AS PRC_XX
FROM ETL010
JOIN generate_series(1,10) AS i ON
IMPUTATION_array[i] IS NOT NULL AND
(IMPUTATION_array[i] <> '' OR i = 1) AND
PRC_array[i] > 0
;
-- Trim des champs text
SELECT base.cti_execute('UPDATE w_ETL010 SET ' ||
array_to_string(base.cti_array_accum(trim_set),',') ||
' WHERE ' ||
array_to_string(base.cti_array_accum(trim_where),' OR '),1)
FROM
(
SELECT
column_name||'=trim('||column_name||')' AS trim_set,
column_name||' IS DISTINCT FROM trim('||column_name||')' AS trim_where
FROM information_schema.columns
WHERE table_name = 'w_etl010' AND
data_type = 'text'
GROUP BY 1,2
) subview
;
-- Identification des Entreprises.
DROP TABLE IF EXISTS temp.x_ref_ent
;
CREATE TABLE temp.x_ref_ent AS
SELECT
ent_code_original AS code_original,
CODE_ETS AS code,
MAX(ETB_SIRET_NOM) AS texte,
MAX(NUM_SIREN_EMPL::text) AS siren,
null::text AS texte_court
FROM w_ETL016
GROUP BY 1,2
;
-- Identification des Etablissements.
DROP TABLE IF EXISTS temp.x_ref_ets
;
CREATE TABLE temp.x_ref_ets AS
SELECT
ent_code_original,
ety_code_original,
ets_code_original AS code_original,
'1' AS code,
MAX(ETB_SIRET_NUMER::text) AS siret,
MAX(ETB_SIRET_NOM) AS texte,
null::text AS texte_court
FROM w_ETL016
GROUP BY 1,2,3,4
;
]]></sqlcmd>
</NODE>
<NODE label="Identification des informations permanentes">
<sqlcmd><![CDATA[
-- Identification des Catégories Socio-Professionnelles.
DROP TABLE IF EXISTS temp.x_ref_categorie_socio_professionnelle
;
CREATE TABLE temp.x_ref_categorie_socio_professionnelle AS
SELECT
LOWER(substr(CLE_TABLE,5)) AS code_original,
LOWER(substr(CLE_TABLE,5)) AS code,
COALESCE(max(LIBELLE_LONG),'') AS texte,
null::text AS texte_court
FROM prod_cegidhru.ETL014
WHERE CODE_TABLE = 'CINEM' AND
CLE_TABLE LIKE '0000%'
GROUP BY 1,2
;
-- Identification des Nationalités.
DROP TABLE IF EXISTS temp.x_ref_nationalite
;
CREATE TABLE temp.x_ref_nationalite AS
SELECT
substr(CLE_TABLE,5) AS code_original,
substr(CLE_TABLE,5) AS code,
COALESCE(max(LIBELLE_LONG),'') AS texte,
null::text AS texte_court
FROM prod_cegidhru.ETL014
WHERE CODE_TABLE = 'LNATI' AND
CLE_TABLE LIKE '0000%' AND
substr(CLE_TABLE,5) = ANY (SELECT NATIONALITE FROM prod_cegidhru.ETL001 GROUP BY 1)
GROUP BY 1,2
;
-- Identification des motifs de début de contrat.
DROP TABLE IF EXISTS temp.x_ref_motif_debut_contrat
;
CREATE TABLE temp.x_ref_motif_debut_contrat AS
SELECT
CODE_TABLE||substr(CLE_TABLE,5) AS code_original,
substr(CLE_TABLE,5) AS code,
COALESCE(max(LIBELLE_LONG),'') AS texte,
null::text AS texte_court
FROM prod_cegidhru.ETL014
WHERE CODE_TABLE = 'GCMEB' AND
CLE_TABLE LIKE '0000%' AND
substr(CLE_TABLE,5) = ANY (SELECT MOTIF_EMBAUCHE FROM w_ETL009 GROUP BY 1)
GROUP BY 1,2
UNION
SELECT
CODE_TABLE||substr(CLE_TABLE,5) AS code_original,
substr(CLE_TABLE,5) AS code,
COALESCE(max(LIBELLE_LONG),'') AS texte,
null::text AS texte_court
FROM prod_cegidhru.ETL014
WHERE CODE_TABLE = 'MRCDD' AND
CLE_TABLE LIKE '0000%' AND
substr(CLE_TABLE,5) = ANY (SELECT MOTIF_CDD FROM w_ETL009 GROUP BY 1)
GROUP BY 1,2
;
-- Identification des motifs de fin de contrat.
DROP TABLE IF EXISTS temp.x_ref_motif_fin_contrat
;
CREATE TABLE temp.x_ref_motif_fin_contrat AS
SELECT
CODE_TABLE||substr(CLE_TABLE,5) AS code_original,
substr(CLE_TABLE,5) AS code,
COALESCE(max(LIBELLE_LONG),'') AS texte,
null::text AS texte_court
FROM prod_cegidhru.ETL014
WHERE CODE_TABLE = 'CCDEP' AND
CLE_TABLE LIKE '0000%' AND
substr(CLE_TABLE,5) = ANY (SELECT DEPART_CAUSE FROM prod_cegidhru.ETL008 GROUP BY 1)
GROUP BY 1,2
;
-- Identification des types de contrat.
DROP TABLE IF EXISTS temp.x_ref_type_contrat
;
CREATE TABLE temp.x_ref_type_contrat AS
SELECT
substr(CLE_TABLE,5) AS code_original,
substr(CLE_TABLE,5) AS code,
COALESCE(max(LIBELLE_LONG),'') AS texte,
null::text AS texte_court
FROM prod_cegidhru.ETL014
WHERE CODE_TABLE = 'CTNAT' AND
CLE_TABLE LIKE '0000%' AND
substr(CLE_TABLE,5) = ANY (SELECT NATURE_CONTRAT FROM w_ETL009 GROUP BY 1)
GROUP BY 1,2
;
-- Identification des groupes cotisants.
DROP TABLE IF EXISTS temp.x_ref_groupe_cotisant
;
CREATE TABLE temp.x_ref_groupe_cotisant AS
SELECT
''::text AS code_original,
''::text AS code,
''::text AS texte,
null::text AS texte_court
LIMIT 0
;
-- Identification des organismes de cotisation
DROP TABLE IF EXISTS temp.x_ref_organisme_cotisation
;
CREATE TABLE temp.x_ref_organisme_cotisation AS
SELECT
''::text AS code_original,
''::text AS code,
''::text AS texte,
null::text AS texte_court
LIMIT 0
;
-- Identification des qualifications
DROP TABLE IF EXISTS temp.x_ref_qualification
;
CREATE TABLE temp.x_ref_qualification AS
SELECT
substr(CLE_TABLE,5) AS code_original,
substr(CLE_TABLE,5) AS code,
COALESCE(max(LIBELLE_LONG),'') AS texte,
null::text AS texte_court
FROM prod_cegidhru.ETL014
WHERE CODE_TABLE = 'CTA54' AND
CLE_TABLE LIKE '0000%' AND
substr(CLE_TABLE,5) = ANY (SELECT CODE_EMPLOI FROM w_ETL009 GROUP BY 1)
GROUP BY 1,2
;
-- Identification des Comptes
-- Identification des situations de famille
DROP TABLE IF EXISTS temp.x_ref_situation_famille
;
CREATE TABLE temp.x_ref_situation_famille AS
SELECT
substr(CLE_TABLE,5) AS code_original,
substr(CLE_TABLE,5) AS code,
COALESCE(max(LIBELLE_LONG),'') AS texte,
null::text AS texte_court
FROM prod_cegidhru.ETL014
WHERE CODE_TABLE = 'CSITF' AND
CLE_TABLE LIKE '0000%' AND
substr(CLE_TABLE,5) = ANY (SELECT CODE_SITUA_FAM FROM prod_cegidhru.ETL001 GROUP BY 1)
GROUP BY 1,2
;
-- Identification des statuts
DROP TABLE IF EXISTS temp.x_ref_statut
;
CREATE TABLE temp.x_ref_statut AS
SELECT
CATEGORIE AS code_original,
CATEGORIE AS code,
null::text AS texte,
null::text AS texte_court
FROM w_ETL009
GROUP BY 1,2
;
-- 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
MODALITE_TRAV::text||'-'||PRC_TEMP_PAR::text AS code_original,
CASE WHEN MODALITE_TRAV = '10' THEN 'TC' ELSE 'TP' END||'-'||PRC_TEMP_PAR::text AS code,
MAX(LIBELLE_LONG || ' (' || PRC_TEMP_PAR::text || '%)') AS texte,
null::text AS texte_court
FROM w_ETL009
LEFT JOIN prod_cegidhru.ETL014 ON CODE_TABLE = 'MODEX' AND CLE_TABLE = '0000'||MODALITE_TRAV
GROUP BY 1,2
;
-- Identification des services
DROP TABLE IF EXISTS temp.x_ref_service
;
CREATE TABLE temp.x_ref_service AS
SELECT
substr(CLE_TABLE,5) AS code_original,
substr(CLE_TABLE,5) AS code,
COALESCE(max(LIBELLE_LONG),'') AS texte,
null::text AS texte_court
FROM prod_cegidhru.ETL014
WHERE CODE_TABLE = 'CTA02' AND
CLE_TABLE LIKE '0000%' AND
substr(CLE_TABLE,5) = ANY (SELECT CTR_A_02 FROM w_ETL009 JOIN w_entreprise ON CODE_ETS = in_entreprise GROUP BY 1)
GROUP BY 1,2
;
-- Identification des spécialités
-- Identification des codes emploi
DROP TABLE IF EXISTS temp.x_ref_code_emploi
;
CREATE TABLE temp.x_ref_code_emploi AS
SELECT
''::text AS code_original,
''::text AS code,
''::text AS texte,
null::text AS texte_court
LIMIT 0
;
-- Identification des types d'horaire
-- 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
-- Identification des précisions du motif d'arrêt
-- Identification des motifs de visite médicale
-- 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_section_analytique
;
CREATE TABLE temp.x_ref_section_analytique AS
WITH ttt AS (
SELECT IMPUTATION_xx
FROM w_ETL010
WHERE IMPUTATION_xx <> ''
GROUP BY 1
)
SELECT
IMPUTATION_xx::bigint AS oid,
IMPUTATION_xx AS code_original,
IMPUTATION_xx AS code,
IMPUTATION_xx AS texte,
null::text AS texte_court
FROM ttt
;
-- Identification des rubriques de paie.
DROP TABLE IF EXISTS temp.x_ref_rubrique
;
CREATE TABLE temp.x_ref_rubrique AS
WITH rub_det_1 AS (
SELECT
NUMERO_RUB,
MAX(LIB_RUBRIQUE) AS LIB_RUBRIQUE,
(
NUMERO_RUB BETWEEN 500 AND 9989 OR
NUMERO_RUB BETWEEN 11000 AND 19800
)
AND
MAX(LIB_RUBRIQUE) NOT LIKE '*%' AS p_detail,
CASE WHEN SUM(abs(INFO_COMP)) <> 0 THEN true ELSE false END p_nombre,
CASE WHEN SUM(abs(BASE)) <> 0 THEN true ELSE false END p_base,
false AS p_heures_payees,
false AS p_heures_travaillees,
(NUMERO_RUB BETWEEN 500 AND 9989 AND
MAX(LIB_RUBRIQUE) NOT LIKE '*%')
OR (SUM(abs(MONTANT_SALAR)) <> 0 OR SUM(abs(MONT_PATRONAL)) <> 0) AS p_masse_salariale,
NUMERO_RUB BETWEEN 500 AND 9989 AND
MAX(LIB_RUBRIQUE) NOT LIKE '*%' AS p_brut,
false AS p_avantage_nature,
false AS p_frais_imposables,
NUMERO_RUB BETWEEN 11000 AND 19800 AND
MAX(LIB_RUBRIQUE) NOT LIKE '*%' AS p_cotisation_salarie,
NUMERO_RUB BETWEEN 11000 AND 19800 AND
MAX(LIB_RUBRIQUE) NOT LIKE '*%' AS p_cotisation_patronale,
false AS p_od_net_salarie,
false AS p_od_net_patronale,
(NUMERO_RUB BETWEEN 500 AND 9989 AND
MAX(LIB_RUBRIQUE) NOT LIKE '*%') OR
(NUMERO_RUB BETWEEN 11000 AND 19000 AND
MAX(LIB_RUBRIQUE) NOT LIKE '*%') AS p_net_imposable,
1 AS c_net_imposable,
(NUMERO_RUB BETWEEN 500 AND 9989 AND
MAX(LIB_RUBRIQUE) NOT LIKE '*%') OR
(NUMERO_RUB BETWEEN 11000 AND 19800 AND
MAX(LIB_RUBRIQUE) NOT LIKE '*%') AS p_net_a_payer,
1 AS c_net_a_payer
FROM w_ETL016
GROUP BY 1
),
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
)
SELECT
NUMERO_RUB::text AS code_original,
to_char(NUMERO_RUB,'FM00000') AS code,
LIB_RUBRIQUE AS texte,
null::text AS texte_court,
NUMERO_RUB::int AS rang_edition,
false AS p_cumul,
p_detail AS p_detail,
p_nombre AS p_nombre,
0 AS s_nombre,
1 AS c_nombre,
p_base 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,
p_heures_payees AS p_heures_payees,
0 AS s_heures_payees,
1 AS c_heures_payees,
p_heures_travaillees AS p_heures_travaillees,
0 AS s_heures_travaillees,
1 AS c_heures_travaillees,
p_masse_salariale AS p_masse_salariale,
case when p_cotisation_patronale OR p_od_net_patronale then 5 else 3 end AS s_masse_salariale,
case when p_cotisation_patronale then -1 else 1 end AS c_masse_salariale,
p_brut AS p_brut,
3 AS s_brut,
1 AS c_brut,
p_avantage_nature AS p_avantage_nature,
3 AS s_avantage_nature,
1 AS c_avantage_nature,
p_frais_imposables AS p_frais_imposables,
3 AS s_frais_imposables,
1 AS c_frais_imposables,
p_cotisation_salarie AS p_cotisation_salarie,
3 AS s_cotisation_salarie,
1 AS c_cotisation_salarie,
p_cotisation_patronale AS p_cotisation_patronale,
5 AS s_cotisation_patronale,
-1 AS c_cotisation_patronale,
p_od_net_salarie AS p_od_net_salarie,
3 AS s_od_net_salarie,
1 AS c_od_net_salarie,
p_od_net_patronale AS p_od_net_patronale,
5 AS s_od_net_patronale,
1 AS c_od_net_patronale,
p_net_imposable AS p_net_imposable,
3 AS s_net_imposable,
c_net_imposable AS c_net_imposable,
p_net_a_payer AS p_net_a_payer,
3 AS s_net_a_payer,
c_net_a_payer AS c_net_a_payer
FROM rub_det_1
UNION ALL
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
;
]]></sqlcmd>
</NODE>
<NODE label="Pré-traitements">
<sqlcmd><![CDATA[
-- ALIMENTATION DES HISTORIQUES
-- SALARIES
DROP TABLE IF EXISTS temp.x_ref_salarie
;
CREATE TABLE temp.x_ref_salarie AS
SELECT
to_char(ETL001.ID_INDIVIDU,'FM90000') AS matricule,
to_char(ETL001.ID_INDIVIDU,'FM90000') AS code,
ETL001.ID_INDIVIDU::text AS code_original,
MAX(coalesce(NUM_SECU, to_char(ETL001.ID_INDIVIDU,'FM90000'))) AS nir,
MAX(CODE_ETS) AS entreprise,
coalesce(MAX(nullif(trim(NOM_USAGE), '')), max(NOM_FAMILLE)) AS nom,
MAX(NOM_FAMILLE) AS nom_naissance,
MAX(PRENOM_SALAR) AS prenom,
COALESCE(MAX(DATE_NAIS)::date, '1962-04-18'::date) AS date_naissance,
MAX(CASE WHEN C_SEXE = '01' THEN 'M' ELSE 'F' END) AS sexe,
MAX(NATIONALITE) AS nationalite,
MAX(CODE_POSTAL) AS code_postal,
MAX(CODE_SITUA_FAM) AS situation_famille,
MAX(DATE_ENTREE) AS date_debut,
MAX(DATE_FIN_CONT) AS date_fin,
MIN(DATE_ENTREE) date_entree_ets,
MAX(DATE_FIN_CONT) AS date_sortie_ets,
MIN(DATE_ANCIEN) AS date_anciennete,
(max(distinct array[DATE_ENTREE::text, (ADRESSE_RUE ||' '|| ADRESSE_RUE_S)::text]))[2] as adresse1,
'' 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_cegidhru.ETL001
JOIN w_ETL009 ETL009 ON ETL001.ID_INDIVIDU = ETL009.ID_INDIVIDU
GROUP BY 1,2,3
;
-- HISTORIQUE DES CONTRATS.
DROP TABLE IF EXISTS temp.x_hst_contrat
;
CREATE TABLE temp.x_hst_contrat AS
SELECT
row_number() over () AS row_id,
ent_code_original,
ets_code_original,
ety_code_original,
sal_code_original,
cnt_code_original,
ID_INDIVIDU::text || '-' || NUMERO_CONTRAT AS numero_contrat,
--cnt_uid, -- contrat universal id.
DATE_ENTREE AS date_debut,
DATE_FIN_CONT AS date_fin
FROM w_ETL009
;
-- HISTORIQUE DES BULLETINS.
DROP TABLE IF EXISTS temp.x_hst_bulletin
;
CREATE TABLE temp.x_hst_bulletin AS
SELECT
ent_code_original,
ets_code_original,
ety_code_original,
sal_code_original,
bul_code_original,
date_debut,
date_fin,
date_paie,
mois_paie,
row_number() over () AS row_id,
row_number() over (order by ety_code_original, sal_code_original, bul_code_original) AS bul_id,
null::text AS cnt_code_original, -- un bulletin est rattaché à un seul et unique contrat.
0 AS est_hors_periode
FROM (
SELECT
ent_code_original,
ets_code_original,
ety_code_original,
sal_code_original,
bul_code_original,
max(date_deb_bul) as date_debut,
max(date_fin_bul) as date_fin,
max(case when to_char(date_fin_bul, 'YYYYMM') = mois_comptable then date_fin_bul else base.cti_last_day((mois_comptable||'01')::date) end) as date_paie,
MAX(mois_comptable) AS mois_paie
FROM w_ETL016
GROUP BY 1,2,3,4,5
ORDER BY 1,2,3,4,5
) w_ETL016
;
-- Association avec le contrat correspondant aux dates.
-- Un bulletin est rattaché à un seul et unique contrat.
WITH toto AS (
SELECT
x_hst_bulletin.row_id,
(max(array[x_hst_contrat.date_fin::text, x_hst_contrat.cnt_code_original]))[2] AS cnt_code_original
FROM temp.x_hst_bulletin
JOIN temp.x_hst_contrat ON 1=1
AND x_hst_contrat.sal_code_original = x_hst_bulletin.sal_code_original
AND base.cti_overlaps(x_hst_contrat.date_debut, x_hst_contrat.date_fin, x_hst_bulletin.date_debut, x_hst_bulletin.date_fin)
GROUP BY 1
)
UPDATE temp.x_hst_bulletin set
cnt_code_original = toto.cnt_code_original
FROM toto
WHERE x_hst_bulletin.row_id = toto.row_id
;
-- Association avec le contrat précédent.
WITH toto AS (
SELECT
x_hst_bulletin.row_id,
(max(array[x_hst_contrat.date_fin::text, x_hst_contrat.cnt_code_original]))[2] AS cnt_code_original
FROM temp.x_hst_bulletin
JOIN temp.x_hst_contrat ON 1=1
AND x_hst_contrat.sal_code_original = x_hst_bulletin.sal_code_original
AND x_hst_contrat.date_fin < x_hst_bulletin.date_debut
WHERE x_hst_bulletin.cnt_code_original is null
GROUP BY 1
)
UPDATE temp.x_hst_bulletin set
cnt_code_original = toto.cnt_code_original,
est_hors_periode = 1
FROM toto
WHERE x_hst_bulletin.row_id = toto.row_id
;
-- Association avec le contrat suivant.
WITH toto AS (
SELECT
x_hst_bulletin.row_id,
(max(array[x_hst_contrat.date_fin::text, x_hst_contrat.cnt_code_original]))[2] AS cnt_code_original
FROM temp.x_hst_bulletin
JOIN temp.x_hst_contrat ON 1=1
AND x_hst_contrat.sal_code_original = x_hst_bulletin.sal_code_original
AND x_hst_contrat.date_fin > x_hst_bulletin.date_debut
WHERE x_hst_bulletin.cnt_code_original is null
GROUP BY 1
)
UPDATE temp.x_hst_bulletin set
cnt_code_original = toto.cnt_code_original,
est_hors_periode = 1
FROM toto
WHERE x_hst_bulletin.row_id = toto.row_id
;
-- 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_etp_contrat
;
CREATE TABLE temp.x_hst_etp_contrat AS
SELECT
w_cnt.ety_code_original,
w_cnt.sal_code_original,
w_cnt.cnt_code_original,
GREATEST(w_cnt.DATE_ENTREE, w_lim_sal.date_debut) AS date_effet,
w_cnt.PRC_TEMP_PAR / 100 AS etp_contrat
FROM w_ETL009 w_cnt
JOIN w_lim_sal ON w_lim_sal.sal_code_original = w_cnt.sal_code_original
;
-- HISTORIQUE CSP.
DROP TABLE IF EXISTS temp.x_hst_categorie_socio_professionnelle
;
CREATE TABLE temp.x_hst_categorie_socio_professionnelle AS
SELECT
w_cnt.ety_code_original,
w_cnt.sal_code_original,
w_cnt.cnt_code_original,
GREATEST(w_cnt.DATE_ENTREE, w_lim_sal.date_debut) AS date_effet,
LOWER(C_EMPLOI_PCSESE) AS categorie_socio_professionnelle_code_original
FROM w_ETL009 w_cnt
JOIN w_lim_sal ON w_lim_sal.sal_code_original = w_cnt.sal_code_original
;
-- HISTORIQUE Motif de début.
DROP TABLE IF EXISTS temp.x_hst_motif_debut_contrat
;
CREATE TABLE temp.x_hst_motif_debut_contrat AS
SELECT
w_cnt.ety_code_original,
w_cnt.sal_code_original,
w_cnt.cnt_code_original,
GREATEST(w_cnt.DATE_ENTREE, w_lim_sal.date_debut) AS date_effet,
CASE
WHEN w_cnt.MOTIF_EMBAUCHE <> '' THEN 'GCMEB' || w_cnt.MOTIF_EMBAUCHE
WHEN w_cnt.MOTIF_CDD <> '' THEN 'MRCDD' || w_cnt.MOTIF_CDD
ELSE '' END AS motif_debut_code_original
FROM w_ETL009 w_cnt
JOIN w_lim_sal ON w_lim_sal.sal_code_original = w_cnt.sal_code_original
;
-- HISTORIQUE Motif de fin.
DROP TABLE IF EXISTS temp.x_hst_motif_fin_contrat
;
CREATE TABLE temp.x_hst_motif_fin_contrat AS
SELECT
w_cnt.ety_code_original,
w_cnt.sal_code_original,
w_cnt.cnt_code_original,
GREATEST(w_cnt.DATE_ENTREE, w_lim_sal.date_debut) AS date_effet,
CASE
WHEN w_cnt.DEPART_CAUSE <> '' THEN 'CCDEP' || w_cnt.DEPART_CAUSE
ELSE '' END AS motif_fin_code_original
FROM w_ETL009 w_cnt
JOIN w_lim_sal ON w_lim_sal.sal_code_original = w_cnt.sal_code_original
;
-- HISTORIQUE Types de contrat.
DROP TABLE IF EXISTS temp.x_hst_type_contrat
;
CREATE TABLE temp.x_hst_type_contrat AS
SELECT
w_cnt.ety_code_original,
w_cnt.sal_code_original,
w_cnt.cnt_code_original,
GREATEST(w_cnt.DATE_ENTREE, w_lim_sal.date_debut) AS date_effet,
w_cnt.NATURE_CONTRAT AS type_contrat_code_original
FROM w_ETL009 w_cnt
JOIN w_lim_sal ON w_lim_sal.sal_code_original = w_cnt.sal_code_original
;
-- -- HISTORIQUE CSP.
-- DROP TABLE IF EXISTS temp.x_hst_organisme_cotisation
-- ;
-- CREATE TABLE temp.x_hst_organisme_cotisation AS
-- SELECT
-- w_cnt.ent_code_original||'-'||w_cnt.ets_code_original AS ety_code_original,
-- w_cnt.sal_code_original,
-- w_cnt.cnt_code_original,
-- greatest(w_cnt.date_debut, w_lim_sal.date_debut) AS date_effet,
-- w_cnt.codinseeemploi2003 AS categorie_socio_professionnelle_code_original
-- FROM w_cnt
-- JOIN w_lim_sal ON w_lim_sal.sal_code_original = w_cnt.sal_code_original
-- ;
-- HISTORIQUE CSP.
DROP TABLE IF EXISTS temp.x_hst_qualification
;
CREATE TABLE temp.x_hst_qualification AS
SELECT
w_cnt.ety_code_original,
w_cnt.sal_code_original,
w_cnt.cnt_code_original,
GREATEST(w_cnt.DATE_ENTREE, w_lim_sal.date_debut) AS date_effet,
w_cnt.CODE_EMPLOI AS qualification_code_original
FROM w_ETL009 w_cnt
JOIN w_lim_sal ON w_lim_sal.sal_code_original = w_cnt.sal_code_original
;
-- HISTORIQUE CSP.
DROP TABLE IF EXISTS temp.x_hst_statut
;
CREATE TABLE temp.x_hst_statut AS
SELECT
w_cnt.ety_code_original,
w_cnt.sal_code_original,
w_cnt.cnt_code_original,
GREATEST(w_cnt.DATE_ENTREE, w_lim_sal.date_debut) AS date_effet,
w_cnt.CATEGORIE AS statut_code_original
FROM w_ETL009 w_cnt
JOIN w_lim_sal ON w_lim_sal.sal_code_original = w_cnt.sal_code_original
;
-- HISTORIQUE CSP.
DROP TABLE IF EXISTS temp.x_hst_type_temps_travail
;
CREATE TABLE temp.x_hst_type_temps_travail AS
SELECT
w_cnt.ety_code_original,
w_cnt.sal_code_original,
w_cnt.cnt_code_original,
GREATEST(w_cnt.DATE_ENTREE, w_lim_sal.date_debut) AS date_effet,
w_cnt.MODALITE_TRAV::text||'-'||w_cnt.PRC_TEMP_PAR::text AS type_temps_travail_code_original
FROM w_ETL009 w_cnt
JOIN w_lim_sal ON w_lim_sal.sal_code_original = w_cnt.sal_code_original
;
-- HISTORIQUE CSP.
DROP TABLE IF EXISTS temp.x_hst_service
;
CREATE TABLE temp.x_hst_service AS
SELECT
w_cnt.ety_code_original,
w_cnt.sal_code_original,
w_cnt.cnt_code_original,
GREATEST(w_cnt.DATE_ENTREE, w_lim_sal.date_debut) AS date_effet,
w_cnt.CTR_A_02 AS service_code_original
FROM w_ETL009 w_cnt
JOIN w_lim_sal ON w_lim_sal.sal_code_original = w_cnt.sal_code_original
;
-- HISTORIQUE CSP.
DROP TABLE IF EXISTS temp.x_hst_code_emploi
;
CREATE TABLE temp.x_hst_code_emploi AS
SELECT
w_cnt.ety_code_original,
w_cnt.sal_code_original,
w_cnt.cnt_code_original,
GREATEST(w_cnt.DATE_ENTREE, w_lim_sal.date_debut) AS date_effet,
''::text AS code_emploi_code_original
FROM w_ETL009 w_cnt
JOIN w_lim_sal ON w_lim_sal.sal_code_original = w_cnt.sal_code_original
;
-- HISTORIQUE GRILLE.
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
;
]]></sqlcmd>
</NODE>
<NODE label="Historique de la paie">
<sqlcmd><![CDATA[
DROP TABLE IF EXISTS temp.x_hst_paie
;
CREATE TABLE temp.x_hst_paie AS
WITH w_cum AS (
SELECT
bul_id,
ety_code_original,
sal_code_original,
cnt_code_original,
bul_code_original,
mois_paie,
date_debut,
date_fin,
date_paie,
unnest(rubriques) AS rub,
unnest(valeurs) AS val
FROM (
SELECT
bulletins.bul_id,
bulletins.ety_code_original,
bulletins.sal_code_original,
bulletins.cnt_code_original,
bulletins.bul_code_original,
bulletins.mois_paie,
bulletins.date_debut,
bulletins.date_fin,
bulletins.date_paie,
array[
'C001',
'C002',
'C008',
'C007',
'C006',
'C004',
'C003',
'C009'] AS rubriques,
array[
COALESCE(nullif(0, 0), 0)::numeric,
COALESCE(nullif(0, 0), 0)::numeric,
COALESCE(nullif(0, 0), 0)::numeric,
COALESCE(nullif(0, 0), 0)::numeric,
COALESCE(nullif(0, 0), 0)::numeric,
COALESCE(nullif(0, 0), 0)::numeric,
COALESCE(nullif(0, 0), 0)::numeric,
COALESCE(nullif(0, 0), 0)::numeric] AS valeurs
FROM temp.x_hst_bulletin AS bulletins
JOIN temp.x_ref_ets ON x_ref_ets.ety_code_original = bulletins.ety_code_original
WHERE bulletins.mois_paie >= 202101
) AS suqb
)
SELECT
bulletins.bul_id,
bulletins.ety_code_original,
bulletins.sal_code_original,
bulletins.cnt_code_original,
bulletins.bul_code_original,
bulletins.date_debut,
bulletins.date_fin,
bulletins.mois_paie AS mois_activite,
bulletins.date_paie,
bulletins.mois_paie,
NUMERO_RUB::text AS rub_code_original,
COALESCE(nullif(BASE, 0), 0)::numeric AS base,
COALESCE(nullif(TAUX_SALAR, 0), 0)::numeric AS txsal,
COALESCE(nullif(MONTANT_SALAR, 0), 0)::numeric AS mntsal,
COALESCE(nullif(TAUX_PATRONAL, 0), 0)::numeric AS txpat,
COALESCE(nullif(MONT_PATRONAL, 0), 0)::numeric AS mntpat
FROM temp.x_hst_bulletin AS bulletins
JOIN temp.x_ref_ets ON x_ref_ets.ety_code_original = bulletins.ety_code_original
JOIN w_ETL016 ON bulletins.bul_code_original = w_ETL016.bul_code_original
WHERE 1=1
AND bulletins.mois_paie >= 202101
AND (1!=1
OR MONTANT_SALAR != 0
OR MONT_PATRONAL != 0
OR BASE != 0)
UNION ALL
SELECT
bul_id,
ety_code_original,
sal_code_original,
cnt_code_original,
bul_code_original,
date_debut,
date_fin,
mois_paie AS mois_activite,
date_paie,
mois_paie,
rub AS rub_code_original,
case when rub in ('C001', 'C002', 'C009') then val::numeric else 0::numeric end AS base,
0 AS txsal,
case
when rub in ('C003', 'C004', 'C008') then val::numeric
when rub = 'C007' then -val::numeric
else 0::numeric end AS mnt_sal,
0 AS txpat,
case when rub = 'C006' then val::numeric else 0::numeric end AS mnt_pat
FROM w_cum
;
]]></sqlcmd>
</NODE>
<NODE label="Ventilation analytique">
<sqlcmd><![CDATA[
-- Recencement de la ventilation ana.
DROP TABLE IF EXISTS temp.x_ventilation
;
CREATE TABLE temp.x_ventilation AS
WITH base AS (
SELECT
x_hst_bulletin.bul_id,
COALESCE(CASE WHEN w_ETL010.IMPUTATION_XX <> '' THEN w_ETL010.IMPUTATION_XX ELSE '0' END::bigint,0) AS section_analytique_id,
w_ETL010.IMPUTATION_XX AS section_analytique_code_original,
COALESCE(nullif(PRC_XX, 0), 100.0) AS pct
FROM temp.x_hst_bulletin
LEFT JOIN w_ETL010 ON 1=1
AND x_hst_bulletin.ety_code_original = w_ETL010.ety_code_original
AND x_hst_bulletin.cnt_code_original = w_ETL010.cnt_code_original
)
, ven AS (
SELECT
bul_id,
section_analytique_id,
section_analytique_code_original,
base.cti_division(pct, sum(pct) over (partition by bul_id)) AS ratio
FROM base
)
SELECT
bul_id,
section_analytique_id,
section_analytique_code_original,
sum(ratio) AS ratio
FROM ven
GROUP BY 1,2,3
;
]]></sqlcmd>
</NODE>
</NODE>
<NODE name="PROD" label="RECUPERATION DES DONNEES DE PRODUCTION">
<NODE name="PROD_COMMON" type="common" />
</NODE>
<NODE name="POST" label="POST-TRAITEMENTS">
<NODE name="DIVERS" type="common"/>
<NODE label="Mise à jour de la table Divers (mois en cours)">
<sqlcmd><![CDATA[
]]></sqlcmd>
</NODE>
<NODE name="POST" type="common"/>
</NODE>
<NODE name="VACUUM" label="REORGANISATION BASE DE DONNEES">
<NODE name="VACUUM" type="common" />
</NODE>
<NODE name="RAZ" label="RAZ BASE">
<NODE name="RAZ" type="common" />
</NODE>
<NODE name="RAZ_ALL" label="RAZ ALL">
<NODE name="RAZ_ALL" type="common" />
</NODE>
</ROOT>