<?xml version="1.0" encoding="ISO-8859-1"?>
|
|
<ROOT>
|
|
<NODE name="INIT" label="INITIALISATIONS">
|
|
<NODE label="Identification des entreprises/etablissements">
|
|
<sqlcmd><![CDATA[
|
|
|
|
|
|
-- Creation d'une table temp des etablissements pour faciliter les futures jointures.
|
|
DROP TABLE IF EXISTS w_ets
|
|
;
|
|
|
|
CREATE TEMP TABLE w_ets AS
|
|
SELECT
|
|
PAIETABLISSEMENT.ID_PAIETABLISSEMENT,
|
|
INTERVENANT.INT_RAISONSOCIALE,
|
|
INTERVENANT.INT_SIRET,
|
|
CLIENT.CLI_NUMERODOSSIER,
|
|
max(PAIETABLISSEMENT.ID_PAIETABLISSEMENT) over (partition by CLIENT.CLI_NUMERODOSSIER) AS ID_PAIETABLISSEMENT2
|
|
FROM prod_silae.PAIETABLISSEMENT
|
|
JOIN prod_silae.INTERVENANT ON INTERVENANT.ID_INTERVENANT = PAIETABLISSEMENT.ID_INTERVENANT
|
|
JOIN prod_silae.CLIENT ON CLIENT.id_CLIENT = PAIETABLISSEMENT.id_CLIENT
|
|
WHERE 1!=1
|
|
OR substr(INT_SIRET, 1, 9) IN (SELECT rhp_in('siren')) -- Soit un ou plusieurs SIREN ont ete defini,
|
|
OR INT_SIRET IN (SELECT rhp_in('siren')) -- et/ou soit un ou plusieurs SIRET,
|
|
OR CLI_NUMERODOSSIER IN (SELECT rhp_in('siren')) -- et/ou soit un ou plusieurs codes etablissement.
|
|
OR ID_PAIETABLISSEMENT IN (SELECT rhp_in('siren')) -- et/ou soit un ou plusieurs codes etablissement.
|
|
GROUP BY 1,2,3,4
|
|
;
|
|
|
|
-- Identification des Entreprises.
|
|
DROP TABLE IF EXISTS temp.x_ref_ent
|
|
;
|
|
|
|
CREATE TABLE temp.x_ref_ent AS
|
|
SELECT
|
|
CLI_NUMERODOSSIER AS code_original,
|
|
CLI_NUMERODOSSIER AS code,
|
|
INT_RAISONSOCIALE AS texte,
|
|
substr(INT_SIRET, 1, 9) AS siren,
|
|
null::text AS texte_court
|
|
FROM w_ets
|
|
GROUP BY 1,2,3,4
|
|
;
|
|
|
|
-- Identification des Etablissements.
|
|
DROP TABLE IF EXISTS temp.x_ref_ets
|
|
;
|
|
|
|
CREATE TABLE temp.x_ref_ets AS
|
|
SELECT
|
|
CLI_NUMERODOSSIER AS ent_code_original,
|
|
CLI_NUMERODOSSIER||'-'||ID_PAIETABLISSEMENT AS ety_code_original,
|
|
ID_PAIETABLISSEMENT AS code_original,
|
|
ID_PAIETABLISSEMENT AS code,
|
|
INT_SIRET AS siret,
|
|
INT_RAISONSOCIALE AS texte,
|
|
null::text AS texte_court
|
|
FROM w_ets
|
|
GROUP BY 1,2,3,4,5,6
|
|
;
|
|
|
|
-- Identification contrats
|
|
DROP TABLE IF EXISTS w_PAISALARIEEMPLOI_ets
|
|
;
|
|
|
|
CREATE TEMP TABLE w_PAISALARIEEMPLOI_ets AS
|
|
SELECT
|
|
PAISALARIEEMPLOI.*,
|
|
CLI_NUMERODOSSIER,
|
|
ID_PAIETABLISSEMENT2
|
|
FROM prod_silae.PAISALARIEEMPLOI
|
|
JOIN w_ets ON w_ets.ID_PAIETABLISSEMENT = PAISALARIEEMPLOI.ID_PAIETABLISSEMENT
|
|
;
|
|
|
|
ANALYSE w_PAISALARIEEMPLOI_ets
|
|
;
|
|
|
|
-- Quelques corrections d'affectation
|
|
SELECT base.cti_execute(
|
|
'UPDATE w_PAISALARIEEMPLOI_ets PAISALARIEEMPLOI
|
|
SET SEM_AFFECT_TYPE3 = new_SEM_AFFECT_TYPE3
|
|
FROM
|
|
(
|
|
SELECT
|
|
ID_PAISALARIEEMPLOI,
|
|
CASE
|
|
WHEN SEM_AFFECT_TYPE3 <> '''' THEN SEM_AFFECT_TYPE3
|
|
WHEN SEM_AFFECT_TYPE1 <> '''' AND
|
|
SEM_AFFECT_TYPE1 = LAG(SEM_AFFECT_TYPE1) OVER (PARTITION BY ID_PAISALARIE ORDER BY ID_PAISALARIEEMPLOI) AND
|
|
LAG(SEM_AFFECT_TYPE3) OVER (PARTITION BY ID_PAISALARIE ORDER BY ID_PAISALARIEEMPLOI) <> ''''
|
|
THEN LAG(SEM_AFFECT_TYPE3) OVER (PARTITION BY ID_PAISALARIE ORDER BY ID_PAISALARIEEMPLOI)
|
|
WHEN SEM_AFFECT_TYPE1 <> '''' AND
|
|
SEM_AFFECT_TYPE1 = LEAD(SEM_AFFECT_TYPE1) OVER (PARTITION BY ID_PAISALARIE ORDER BY ID_PAISALARIEEMPLOI)
|
|
THEN LEAD(SEM_AFFECT_TYPE3) OVER (PARTITION BY ID_PAISALARIE ORDER BY ID_PAISALARIEEMPLOI)
|
|
ELSE '''' END AS new_SEM_AFFECT_TYPE3
|
|
FROM w_PAISALARIEEMPLOI_ets PAISALARIEEMPLOI
|
|
) subview
|
|
WHERE PAISALARIEEMPLOI.ID_PAISALARIEEMPLOI = subview.ID_PAISALARIEEMPLOI AND
|
|
COALESCE(PAISALARIEEMPLOI.SEM_AFFECT_TYPE3,'''') IS DISTINCT FROM new_SEM_AFFECT_TYPE3 AND
|
|
new_SEM_AFFECT_TYPE3 <> ''''
|
|
',50)
|
|
;
|
|
|
|
]]></sqlcmd>
|
|
</NODE>
|
|
<NODE label="Identification des informations permanentes">
|
|
<sqlcmd><![CDATA[
|
|
|
|
-- Configuration
|
|
INSERT INTO rh.t_divers (code, texte, valeur, description)
|
|
SELECT *
|
|
FROM
|
|
(
|
|
SELECT 'SILAE_SERVICE'::text AS code, 'Source service SILAE'::text AS texte, '' AS valeur, 'Champ source service SILAE (Table PAISALARIEEMPLOI.AFFECT_TYPEx)'::text AS description
|
|
UNION
|
|
SELECT 'SILAE_CODEEMPLOI'::text AS code, 'Source emploi SILAE'::text AS texte, '' AS valeur, 'Champ source code emploi SILAE (Table PAISALARIEEMPLOI.AFFECT_TYPEx)'::text AS description
|
|
UNION
|
|
SELECT 'SILAE_SPECIALITE'::text AS code, 'Source spécialité SILAE'::text AS texte, '' AS valeur, 'Champ source spécialité SILAE (Table PAISALARIEEMPLOI.AFFECT_TYPEx)'::text AS description
|
|
UNION
|
|
SELECT 'SILAE_RUBRIQUE'::text AS code, 'Source rubrique SILAE'::text AS texte, '1' AS valeur, '1=BLIZONE+BLI_CODELIBELLE+BLI_MARQUE1+BLI_MARQUEINTERNE 2=BLIZONE+BLI_CODELIBELLE+BLI_LIBELLE'::text AS description
|
|
) subview
|
|
WHERE code NOT IN (SELECT code FROM rh.t_divers WHERE code IS NOT NULL)
|
|
;
|
|
|
|
-- Repercution affectations selon prececente puis suivante
|
|
|
|
|
|
|
|
|
|
|
|
-- Maj des categories socio-professionnelles.
|
|
DROP TABLE IF EXISTS temp.x_ref_categorie_socio_professionnelle
|
|
;
|
|
|
|
CREATE TABLE temp.x_ref_categorie_socio_professionnelle AS
|
|
SELECT
|
|
lower(SEM_S41_G01_00_011_001) AS code_original,
|
|
lower(SEM_S41_G01_00_011_001) AS code,
|
|
lower(SEM_S41_G01_00_011_001) AS texte,
|
|
null::text AS texte_court
|
|
FROM w_PAISALARIEEMPLOI_ets PAISALARIEEMPLOI
|
|
GROUP BY 1,2,3,4
|
|
;
|
|
|
|
-- Identification des Nationalites.
|
|
DROP TABLE IF EXISTS temp.x_ref_nationalite
|
|
;
|
|
|
|
CREATE TABLE temp.x_ref_nationalite AS
|
|
SELECT
|
|
INT_PAYSNATIONALITEISO AS code_original,
|
|
INT_PAYSNATIONALITEISO AS code,
|
|
MAX(INT_PAYSNATIONALITE) AS texte,
|
|
null::text AS texte_court
|
|
FROM prod_silae.INTERVENANT
|
|
WHERE INT_PAYSNATIONALITEISO is not null
|
|
GROUP BY 1
|
|
;
|
|
|
|
-- Identification des motifs de debut de contrat.
|
|
DROP TABLE IF EXISTS temp.x_ref_motif_debut_contrat
|
|
;
|
|
|
|
CREATE TABLE temp.x_ref_motif_debut_contrat AS
|
|
SELECT
|
|
SEM_CDDMOTIF AS code_original,
|
|
SEM_CDDMOTIF AS code,
|
|
null::text AS texte,
|
|
null::text AS texte_court
|
|
FROM w_PAISALARIEEMPLOI_ets PAISALARIEEMPLOI
|
|
GROUP BY 1,2,3,4
|
|
;
|
|
|
|
-- 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
|
|
SEM_MOTIFRUPTURECONTRAT AS code_original,
|
|
SEM_MOTIFRUPTURECONTRAT AS code,
|
|
null::text AS texte,
|
|
null::text AS texte_court
|
|
FROM w_PAISALARIEEMPLOI_ets PAISALARIEEMPLOI
|
|
GROUP BY 1,2,3,4
|
|
;
|
|
|
|
-- Identification des types de contrat.
|
|
DROP TABLE IF EXISTS temp.x_ref_type_contrat
|
|
;
|
|
|
|
CREATE TABLE temp.x_ref_type_contrat AS
|
|
SELECT
|
|
SEM_S41_G01_00_012_001 AS code_original,
|
|
SEM_S41_G01_00_012_001 AS code,
|
|
null::text AS texte,
|
|
null::text AS texte_court
|
|
FROM w_PAISALARIEEMPLOI_ets PAISALARIEEMPLOI
|
|
GROUP BY 1,2,3,4
|
|
;
|
|
|
|
-- Identification des groupes cotisants.
|
|
DROP TABLE IF EXISTS temp.x_ref_groupe_cotisant
|
|
;
|
|
|
|
CREATE TABLE temp.x_ref_groupe_cotisant AS
|
|
SELECT
|
|
null::text AS code_original,
|
|
null::text AS code,
|
|
null::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
|
|
null::text AS code_original,
|
|
null::text AS code,
|
|
null::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
|
|
replace(SEM_S41_G01_00_010::text,' ','_') AS code_original,
|
|
replace(SEM_S41_G01_00_010::text,' ','_') AS code,
|
|
max(SEM_S41_G01_00_010) AS texte,
|
|
null::text AS texte_court
|
|
FROM w_PAISALARIEEMPLOI_ets PAISALARIEEMPLOI
|
|
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
|
|
INT_SITUATIONFAMILIALE AS code_original,
|
|
INT_SITUATIONFAMILIALE AS code,
|
|
null::text AS texte,
|
|
null::text AS texte_court
|
|
FROM prod_silae.INTERVENANT
|
|
GROUP BY 1,2,3,4
|
|
;
|
|
|
|
-- Identification des statuts
|
|
DROP TABLE IF EXISTS temp.x_ref_statut
|
|
;
|
|
|
|
CREATE TABLE temp.x_ref_statut AS
|
|
SELECT
|
|
SEM_S41_G01_00_014 AS code_original,
|
|
SEM_S41_G01_00_014 AS code,
|
|
null::text AS texte,
|
|
null::text AS texte_court
|
|
FROM w_PAISALARIEEMPLOI_ets PAISALARIEEMPLOI
|
|
GROUP BY 1,2,3,4
|
|
;
|
|
|
|
-- 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
|
|
COALESCE(nullif(SEM_HORAIREMENSUEL, 0), 151.67)::text AS code_original,
|
|
COALESCE(nullif(SEM_HORAIREMENSUEL, 0), 151.67)::text AS code,
|
|
COALESCE(nullif(SEM_HORAIREMENSUEL, 0), 151.67)::text AS texte,
|
|
null::text AS texte_court
|
|
FROM w_PAISALARIEEMPLOI_ets PAISALARIEEMPLOI
|
|
GROUP BY 1,2,3,4
|
|
;
|
|
|
|
-- Identification des services
|
|
DROP TABLE IF EXISTS temp.x_ref_service
|
|
;
|
|
|
|
CREATE TABLE temp.x_ref_service AS
|
|
|
|
SELECT
|
|
MAX(COALESCE(
|
|
CASE
|
|
WHEN t_divers.valeur = 'AFFECT_TYPE1' AND SEM_AFFECT_TYPE1 <> '' THEN CASE WHEN POSITION('-' IN SEM_AFFECT_TYPE1) BETWEEN 4 AND 7 THEN split_part(SEM_AFFECT_TYPE1,'-',1) ELSE SEM_AFFECT_TYPE1 END
|
|
WHEN t_divers.valeur = 'AFFECT_TYPE2' AND SEM_AFFECT_TYPE2 <> '' THEN CASE WHEN POSITION('-' IN SEM_AFFECT_TYPE2) BETWEEN 4 AND 7 THEN split_part(SEM_AFFECT_TYPE2,'-',1) ELSE SEM_AFFECT_TYPE2 END
|
|
WHEN t_divers.valeur = 'AFFECT_TYPE3' AND SEM_AFFECT_TYPE3 <> '' THEN CASE WHEN POSITION('-' IN SEM_AFFECT_TYPE3) BETWEEN 4 AND 7 THEN split_part(SEM_AFFECT_TYPE3,'-',1) ELSE SEM_AFFECT_TYPE3 END
|
|
WHEN t_divers.valeur = 'AFFECT_TYPE4' AND SEM_AFFECT_TYPE4 <> '' THEN CASE WHEN POSITION('-' IN SEM_AFFECT_TYPE4) BETWEEN 4 AND 7 THEN split_part(SEM_AFFECT_TYPE4,'-',1) ELSE SEM_AFFECT_TYPE4 END
|
|
WHEN t_divers.valeur = 'AFFECT_TYPE5' AND SEM_AFFECT_TYPE5 <> '' THEN CASE WHEN POSITION('-' IN SEM_AFFECT_TYPE5) BETWEEN 4 AND 7 THEN split_part(SEM_AFFECT_TYPE5,'-',1) ELSE SEM_AFFECT_TYPE5 END
|
|
WHEN t_divers.valeur = 'AFFECT_TYPE6' AND SEM_AFFECT_TYPE6 <> '' THEN CASE WHEN POSITION('-' IN SEM_AFFECT_TYPE6) BETWEEN 4 AND 7 THEN split_part(SEM_AFFECT_TYPE6,'-',1) ELSE SEM_AFFECT_TYPE6 END
|
|
ELSE NULL END,
|
|
chr(1)||'*'))
|
|
AS code,
|
|
COALESCE(
|
|
CASE
|
|
WHEN t_divers.valeur = 'AFFECT_TYPE1' AND SEM_AFFECT_TYPE1 <> '' THEN SEM_AFFECT_TYPE1
|
|
WHEN t_divers.valeur = 'AFFECT_TYPE2' AND SEM_AFFECT_TYPE2 <> '' THEN SEM_AFFECT_TYPE2
|
|
WHEN t_divers.valeur = 'AFFECT_TYPE3' AND SEM_AFFECT_TYPE3 <> '' THEN SEM_AFFECT_TYPE3
|
|
WHEN t_divers.valeur = 'AFFECT_TYPE4' AND SEM_AFFECT_TYPE4 <> '' THEN SEM_AFFECT_TYPE4
|
|
WHEN t_divers.valeur = 'AFFECT_TYPE5' AND SEM_AFFECT_TYPE5 <> '' THEN SEM_AFFECT_TYPE5
|
|
WHEN t_divers.valeur = 'AFFECT_TYPE6' AND SEM_AFFECT_TYPE6 <> '' THEN SEM_AFFECT_TYPE6
|
|
ELSE NULL END,
|
|
chr(1)||'*')
|
|
AS code_original,
|
|
MAX(COALESCE(
|
|
CASE
|
|
WHEN t_divers.valeur = 'AFFECT_TYPE1' AND SEM_AFFECT_TYPE1 <> '' THEN CASE WHEN POSITION('-' IN SEM_AFFECT_TYPE1) BETWEEN 4 AND 7 THEN split_part(SEM_AFFECT_TYPE1,'-',2) ELSE SEM_AFFECT_TYPE1 END
|
|
WHEN t_divers.valeur = 'AFFECT_TYPE2' AND SEM_AFFECT_TYPE2 <> '' THEN CASE WHEN POSITION('-' IN SEM_AFFECT_TYPE2) BETWEEN 4 AND 7 THEN split_part(SEM_AFFECT_TYPE2,'-',2) ELSE SEM_AFFECT_TYPE2 END
|
|
WHEN t_divers.valeur = 'AFFECT_TYPE3' AND SEM_AFFECT_TYPE3 <> '' THEN CASE WHEN POSITION('-' IN SEM_AFFECT_TYPE3) BETWEEN 4 AND 7 THEN split_part(SEM_AFFECT_TYPE3,'-',2) ELSE SEM_AFFECT_TYPE3 END
|
|
WHEN t_divers.valeur = 'AFFECT_TYPE4' AND SEM_AFFECT_TYPE4 <> '' THEN CASE WHEN POSITION('-' IN SEM_AFFECT_TYPE4) BETWEEN 4 AND 7 THEN split_part(SEM_AFFECT_TYPE4,'-',2) ELSE SEM_AFFECT_TYPE4 END
|
|
WHEN t_divers.valeur = 'AFFECT_TYPE5' AND SEM_AFFECT_TYPE5 <> '' THEN CASE WHEN POSITION('-' IN SEM_AFFECT_TYPE5) BETWEEN 4 AND 7 THEN split_part(SEM_AFFECT_TYPE5,'-',2) ELSE SEM_AFFECT_TYPE5 END
|
|
WHEN t_divers.valeur = 'AFFECT_TYPE6' AND SEM_AFFECT_TYPE6 <> '' THEN CASE WHEN POSITION('-' IN SEM_AFFECT_TYPE6) BETWEEN 4 AND 7 THEN split_part(SEM_AFFECT_TYPE6,'-',2) ELSE SEM_AFFECT_TYPE6 END
|
|
ELSE NULL END,
|
|
chr(1)||'*'))
|
|
AS texte,
|
|
MAX(COALESCE(
|
|
CASE
|
|
WHEN t_divers.valeur = 'AFFECT_TYPE1' AND SEM_AFFECT_TYPE1 <> '' THEN CASE WHEN POSITION('-' IN SEM_AFFECT_TYPE1) BETWEEN 4 AND 7 THEN split_part(SEM_AFFECT_TYPE1,'-',2) ELSE SEM_AFFECT_TYPE1 END
|
|
WHEN t_divers.valeur = 'AFFECT_TYPE2' AND SEM_AFFECT_TYPE2 <> '' THEN CASE WHEN POSITION('-' IN SEM_AFFECT_TYPE2) BETWEEN 4 AND 7 THEN split_part(SEM_AFFECT_TYPE2,'-',2) ELSE SEM_AFFECT_TYPE2 END
|
|
WHEN t_divers.valeur = 'AFFECT_TYPE3' AND SEM_AFFECT_TYPE3 <> '' THEN CASE WHEN POSITION('-' IN SEM_AFFECT_TYPE3) BETWEEN 4 AND 7 THEN split_part(SEM_AFFECT_TYPE3,'-',2) ELSE SEM_AFFECT_TYPE3 END
|
|
WHEN t_divers.valeur = 'AFFECT_TYPE4' AND SEM_AFFECT_TYPE1 <> '' THEN CASE WHEN POSITION('-' IN SEM_AFFECT_TYPE4) BETWEEN 4 AND 7 THEN split_part(SEM_AFFECT_TYPE4,'-',2) ELSE SEM_AFFECT_TYPE4 END
|
|
WHEN t_divers.valeur = 'AFFECT_TYPE5' AND SEM_AFFECT_TYPE2 <> '' THEN CASE WHEN POSITION('-' IN SEM_AFFECT_TYPE5) BETWEEN 4 AND 7 THEN split_part(SEM_AFFECT_TYPE5,'-',2) ELSE SEM_AFFECT_TYPE5 END
|
|
WHEN t_divers.valeur = 'AFFECT_TYPE6' AND SEM_AFFECT_TYPE3 <> '' THEN CASE WHEN POSITION('-' IN SEM_AFFECT_TYPE6) BETWEEN 4 AND 7 THEN split_part(SEM_AFFECT_TYPE6,'-',2) ELSE SEM_AFFECT_TYPE6 END
|
|
ELSE NULL END,
|
|
chr(1)||'*'))
|
|
AS texte_court
|
|
FROM w_PAISALARIEEMPLOI_ets PAISALARIEEMPLOI
|
|
JOIN rh.t_divers ON t_divers.code = 'SILAE_SERVICE'
|
|
GROUP BY 2
|
|
;
|
|
|
|
-- Identification des specialites
|
|
DROP TABLE IF EXISTS temp.x_ref_specialite
|
|
;
|
|
|
|
CREATE TABLE temp.x_ref_specialite AS
|
|
|
|
SELECT
|
|
MAX(COALESCE(
|
|
CASE
|
|
WHEN t_divers.valeur = 'AFFECT_TYPE1' AND SEM_AFFECT_TYPE1 <> '' THEN CASE WHEN POSITION('-' IN SEM_AFFECT_TYPE1) BETWEEN 4 AND 7 THEN split_part(SEM_AFFECT_TYPE1,'-',1) ELSE SEM_AFFECT_TYPE1 END
|
|
WHEN t_divers.valeur = 'AFFECT_TYPE2' AND SEM_AFFECT_TYPE2 <> '' THEN CASE WHEN POSITION('-' IN SEM_AFFECT_TYPE2) BETWEEN 4 AND 7 THEN split_part(SEM_AFFECT_TYPE2,'-',1) ELSE SEM_AFFECT_TYPE2 END
|
|
WHEN t_divers.valeur = 'AFFECT_TYPE3' AND SEM_AFFECT_TYPE3 <> '' THEN CASE WHEN POSITION('-' IN SEM_AFFECT_TYPE3) BETWEEN 4 AND 7 THEN split_part(SEM_AFFECT_TYPE3,'-',1) ELSE SEM_AFFECT_TYPE3 END
|
|
WHEN t_divers.valeur = 'AFFECT_TYPE4' AND SEM_AFFECT_TYPE4 <> '' THEN CASE WHEN POSITION('-' IN SEM_AFFECT_TYPE4) BETWEEN 4 AND 7 THEN split_part(SEM_AFFECT_TYPE4,'-',1) ELSE SEM_AFFECT_TYPE4 END
|
|
WHEN t_divers.valeur = 'AFFECT_TYPE5' AND SEM_AFFECT_TYPE5 <> '' THEN CASE WHEN POSITION('-' IN SEM_AFFECT_TYPE5) BETWEEN 4 AND 7 THEN split_part(SEM_AFFECT_TYPE5,'-',1) ELSE SEM_AFFECT_TYPE5 END
|
|
WHEN t_divers.valeur = 'AFFECT_TYPE6' AND SEM_AFFECT_TYPE6 <> '' THEN CASE WHEN POSITION('-' IN SEM_AFFECT_TYPE6) BETWEEN 4 AND 7 THEN split_part(SEM_AFFECT_TYPE6,'-',1) ELSE SEM_AFFECT_TYPE6 END
|
|
ELSE NULL END,
|
|
chr(1)||'*'))
|
|
AS code,
|
|
COALESCE(
|
|
CASE
|
|
WHEN t_divers.valeur = 'AFFECT_TYPE1' AND SEM_AFFECT_TYPE1 <> '' THEN SEM_AFFECT_TYPE1
|
|
WHEN t_divers.valeur = 'AFFECT_TYPE2' AND SEM_AFFECT_TYPE2 <> '' THEN SEM_AFFECT_TYPE2
|
|
WHEN t_divers.valeur = 'AFFECT_TYPE3' AND SEM_AFFECT_TYPE3 <> '' THEN SEM_AFFECT_TYPE3
|
|
WHEN t_divers.valeur = 'AFFECT_TYPE4' AND SEM_AFFECT_TYPE4 <> '' THEN SEM_AFFECT_TYPE4
|
|
WHEN t_divers.valeur = 'AFFECT_TYPE5' AND SEM_AFFECT_TYPE5 <> '' THEN SEM_AFFECT_TYPE5
|
|
WHEN t_divers.valeur = 'AFFECT_TYPE6' AND SEM_AFFECT_TYPE6 <> '' THEN SEM_AFFECT_TYPE6
|
|
ELSE NULL END,
|
|
chr(1)||'*')
|
|
AS code_original,
|
|
MAX(COALESCE(
|
|
CASE
|
|
WHEN t_divers.valeur = 'AFFECT_TYPE1' AND SEM_AFFECT_TYPE1 <> '' THEN CASE WHEN POSITION('-' IN SEM_AFFECT_TYPE1) BETWEEN 4 AND 7 THEN split_part(SEM_AFFECT_TYPE1,'-',2) ELSE SEM_AFFECT_TYPE1 END
|
|
WHEN t_divers.valeur = 'AFFECT_TYPE2' AND SEM_AFFECT_TYPE2 <> '' THEN CASE WHEN POSITION('-' IN SEM_AFFECT_TYPE2) BETWEEN 4 AND 7 THEN split_part(SEM_AFFECT_TYPE2,'-',2) ELSE SEM_AFFECT_TYPE2 END
|
|
WHEN t_divers.valeur = 'AFFECT_TYPE3' AND SEM_AFFECT_TYPE3 <> '' THEN CASE WHEN POSITION('-' IN SEM_AFFECT_TYPE3) BETWEEN 4 AND 7 THEN split_part(SEM_AFFECT_TYPE3,'-',2) ELSE SEM_AFFECT_TYPE3 END
|
|
WHEN t_divers.valeur = 'AFFECT_TYPE4' AND SEM_AFFECT_TYPE4 <> '' THEN CASE WHEN POSITION('-' IN SEM_AFFECT_TYPE4) BETWEEN 4 AND 7 THEN split_part(SEM_AFFECT_TYPE4,'-',2) ELSE SEM_AFFECT_TYPE4 END
|
|
WHEN t_divers.valeur = 'AFFECT_TYPE5' AND SEM_AFFECT_TYPE5 <> '' THEN CASE WHEN POSITION('-' IN SEM_AFFECT_TYPE5) BETWEEN 4 AND 7 THEN split_part(SEM_AFFECT_TYPE5,'-',2) ELSE SEM_AFFECT_TYPE5 END
|
|
WHEN t_divers.valeur = 'AFFECT_TYPE6' AND SEM_AFFECT_TYPE6 <> '' THEN CASE WHEN POSITION('-' IN SEM_AFFECT_TYPE6) BETWEEN 4 AND 7 THEN split_part(SEM_AFFECT_TYPE6,'-',2) ELSE SEM_AFFECT_TYPE6 END
|
|
ELSE NULL END,
|
|
chr(1)||'*'))
|
|
AS texte,
|
|
MAX(COALESCE(
|
|
CASE
|
|
WHEN t_divers.valeur = 'AFFECT_TYPE1' AND SEM_AFFECT_TYPE1 <> '' THEN CASE WHEN POSITION('-' IN SEM_AFFECT_TYPE1) BETWEEN 4 AND 7 THEN split_part(SEM_AFFECT_TYPE1,'-',2) ELSE SEM_AFFECT_TYPE1 END
|
|
WHEN t_divers.valeur = 'AFFECT_TYPE2' AND SEM_AFFECT_TYPE2 <> '' THEN CASE WHEN POSITION('-' IN SEM_AFFECT_TYPE2) BETWEEN 4 AND 7 THEN split_part(SEM_AFFECT_TYPE2,'-',2) ELSE SEM_AFFECT_TYPE2 END
|
|
WHEN t_divers.valeur = 'AFFECT_TYPE3' AND SEM_AFFECT_TYPE3 <> '' THEN CASE WHEN POSITION('-' IN SEM_AFFECT_TYPE3) BETWEEN 4 AND 7 THEN split_part(SEM_AFFECT_TYPE3,'-',2) ELSE SEM_AFFECT_TYPE3 END
|
|
WHEN t_divers.valeur = 'AFFECT_TYPE4' AND SEM_AFFECT_TYPE1 <> '' THEN CASE WHEN POSITION('-' IN SEM_AFFECT_TYPE4) BETWEEN 4 AND 7 THEN split_part(SEM_AFFECT_TYPE4,'-',2) ELSE SEM_AFFECT_TYPE4 END
|
|
WHEN t_divers.valeur = 'AFFECT_TYPE5' AND SEM_AFFECT_TYPE2 <> '' THEN CASE WHEN POSITION('-' IN SEM_AFFECT_TYPE5) BETWEEN 4 AND 7 THEN split_part(SEM_AFFECT_TYPE5,'-',2) ELSE SEM_AFFECT_TYPE5 END
|
|
WHEN t_divers.valeur = 'AFFECT_TYPE6' AND SEM_AFFECT_TYPE3 <> '' THEN CASE WHEN POSITION('-' IN SEM_AFFECT_TYPE6) BETWEEN 4 AND 7 THEN split_part(SEM_AFFECT_TYPE6,'-',2) ELSE SEM_AFFECT_TYPE6 END
|
|
ELSE NULL END,
|
|
chr(1)||'*'))
|
|
AS texte_court
|
|
FROM w_PAISALARIEEMPLOI_ets PAISALARIEEMPLOI
|
|
JOIN rh.t_divers ON t_divers.code = 'SILAE_SPECIALITE'
|
|
GROUP BY 2
|
|
;
|
|
|
|
-- Identification des codes emploi
|
|
DROP TABLE IF EXISTS temp.x_ref_code_emploi
|
|
;
|
|
|
|
CREATE TABLE temp.x_ref_code_emploi AS
|
|
|
|
SELECT
|
|
MAX(COALESCE(
|
|
CASE
|
|
WHEN t_divers.valeur = 'AFFECT_TYPE1' AND SEM_AFFECT_TYPE1 <> '' THEN CASE WHEN POSITION('-' IN SEM_AFFECT_TYPE1) BETWEEN 4 AND 7 THEN split_part(SEM_AFFECT_TYPE1,'-',1) ELSE SEM_AFFECT_TYPE1 END
|
|
WHEN t_divers.valeur = 'AFFECT_TYPE2' AND SEM_AFFECT_TYPE2 <> '' THEN CASE WHEN POSITION('-' IN SEM_AFFECT_TYPE2) BETWEEN 4 AND 7 THEN split_part(SEM_AFFECT_TYPE2,'-',1) ELSE SEM_AFFECT_TYPE2 END
|
|
WHEN t_divers.valeur = 'AFFECT_TYPE3' AND SEM_AFFECT_TYPE3 <> '' THEN CASE WHEN POSITION('-' IN SEM_AFFECT_TYPE3) BETWEEN 4 AND 7 THEN split_part(SEM_AFFECT_TYPE3,'-',1) ELSE SEM_AFFECT_TYPE3 END
|
|
WHEN t_divers.valeur = 'AFFECT_TYPE4' AND SEM_AFFECT_TYPE4 <> '' THEN CASE WHEN POSITION('-' IN SEM_AFFECT_TYPE4) BETWEEN 4 AND 7 THEN split_part(SEM_AFFECT_TYPE4,'-',1) ELSE SEM_AFFECT_TYPE4 END
|
|
WHEN t_divers.valeur = 'AFFECT_TYPE5' AND SEM_AFFECT_TYPE5 <> '' THEN CASE WHEN POSITION('-' IN SEM_AFFECT_TYPE5) BETWEEN 4 AND 7 THEN split_part(SEM_AFFECT_TYPE5,'-',1) ELSE SEM_AFFECT_TYPE5 END
|
|
WHEN t_divers.valeur = 'AFFECT_TYPE6' AND SEM_AFFECT_TYPE6 <> '' THEN CASE WHEN POSITION('-' IN SEM_AFFECT_TYPE6) BETWEEN 4 AND 7 THEN split_part(SEM_AFFECT_TYPE6,'-',1) ELSE SEM_AFFECT_TYPE6 END
|
|
ELSE NULL END,
|
|
chr(1)||'*'))
|
|
AS code,
|
|
COALESCE(
|
|
CASE
|
|
WHEN t_divers.valeur = 'AFFECT_TYPE1' AND SEM_AFFECT_TYPE1 <> '' THEN SEM_AFFECT_TYPE1
|
|
WHEN t_divers.valeur = 'AFFECT_TYPE2' AND SEM_AFFECT_TYPE2 <> '' THEN SEM_AFFECT_TYPE2
|
|
WHEN t_divers.valeur = 'AFFECT_TYPE3' AND SEM_AFFECT_TYPE3 <> '' THEN SEM_AFFECT_TYPE3
|
|
WHEN t_divers.valeur = 'AFFECT_TYPE4' AND SEM_AFFECT_TYPE4 <> '' THEN SEM_AFFECT_TYPE4
|
|
WHEN t_divers.valeur = 'AFFECT_TYPE5' AND SEM_AFFECT_TYPE5 <> '' THEN SEM_AFFECT_TYPE5
|
|
WHEN t_divers.valeur = 'AFFECT_TYPE6' AND SEM_AFFECT_TYPE6 <> '' THEN SEM_AFFECT_TYPE6
|
|
ELSE NULL END,
|
|
chr(1)||'*')
|
|
AS code_original,
|
|
MAX(COALESCE(
|
|
CASE
|
|
WHEN t_divers.valeur = 'AFFECT_TYPE1' AND SEM_AFFECT_TYPE1 <> '' THEN CASE WHEN POSITION('-' IN SEM_AFFECT_TYPE1) BETWEEN 4 AND 7 THEN split_part(SEM_AFFECT_TYPE1,'-',2) ELSE SEM_AFFECT_TYPE1 END
|
|
WHEN t_divers.valeur = 'AFFECT_TYPE2' AND SEM_AFFECT_TYPE2 <> '' THEN CASE WHEN POSITION('-' IN SEM_AFFECT_TYPE2) BETWEEN 4 AND 7 THEN split_part(SEM_AFFECT_TYPE2,'-',2) ELSE SEM_AFFECT_TYPE2 END
|
|
WHEN t_divers.valeur = 'AFFECT_TYPE3' AND SEM_AFFECT_TYPE3 <> '' THEN CASE WHEN POSITION('-' IN SEM_AFFECT_TYPE3) BETWEEN 4 AND 7 THEN split_part(SEM_AFFECT_TYPE3,'-',2) ELSE SEM_AFFECT_TYPE3 END
|
|
WHEN t_divers.valeur = 'AFFECT_TYPE4' AND SEM_AFFECT_TYPE4 <> '' THEN CASE WHEN POSITION('-' IN SEM_AFFECT_TYPE4) BETWEEN 4 AND 7 THEN split_part(SEM_AFFECT_TYPE4,'-',2) ELSE SEM_AFFECT_TYPE4 END
|
|
WHEN t_divers.valeur = 'AFFECT_TYPE5' AND SEM_AFFECT_TYPE5 <> '' THEN CASE WHEN POSITION('-' IN SEM_AFFECT_TYPE5) BETWEEN 4 AND 7 THEN split_part(SEM_AFFECT_TYPE5,'-',2) ELSE SEM_AFFECT_TYPE5 END
|
|
WHEN t_divers.valeur = 'AFFECT_TYPE6' AND SEM_AFFECT_TYPE6 <> '' THEN CASE WHEN POSITION('-' IN SEM_AFFECT_TYPE6) BETWEEN 4 AND 7 THEN split_part(SEM_AFFECT_TYPE6,'-',2) ELSE SEM_AFFECT_TYPE6 END
|
|
ELSE NULL END,
|
|
chr(1)||'*'))
|
|
AS texte,
|
|
MAX(COALESCE(
|
|
CASE
|
|
WHEN t_divers.valeur = 'AFFECT_TYPE1' AND SEM_AFFECT_TYPE1 <> '' THEN CASE WHEN POSITION('-' IN SEM_AFFECT_TYPE1) BETWEEN 4 AND 7 THEN split_part(SEM_AFFECT_TYPE1,'-',2) ELSE SEM_AFFECT_TYPE1 END
|
|
WHEN t_divers.valeur = 'AFFECT_TYPE2' AND SEM_AFFECT_TYPE2 <> '' THEN CASE WHEN POSITION('-' IN SEM_AFFECT_TYPE2) BETWEEN 4 AND 7 THEN split_part(SEM_AFFECT_TYPE2,'-',2) ELSE SEM_AFFECT_TYPE2 END
|
|
WHEN t_divers.valeur = 'AFFECT_TYPE3' AND SEM_AFFECT_TYPE3 <> '' THEN CASE WHEN POSITION('-' IN SEM_AFFECT_TYPE3) BETWEEN 4 AND 7 THEN split_part(SEM_AFFECT_TYPE3,'-',2) ELSE SEM_AFFECT_TYPE3 END
|
|
WHEN t_divers.valeur = 'AFFECT_TYPE4' AND SEM_AFFECT_TYPE1 <> '' THEN CASE WHEN POSITION('-' IN SEM_AFFECT_TYPE4) BETWEEN 4 AND 7 THEN split_part(SEM_AFFECT_TYPE4,'-',2) ELSE SEM_AFFECT_TYPE4 END
|
|
WHEN t_divers.valeur = 'AFFECT_TYPE5' AND SEM_AFFECT_TYPE2 <> '' THEN CASE WHEN POSITION('-' IN SEM_AFFECT_TYPE5) BETWEEN 4 AND 7 THEN split_part(SEM_AFFECT_TYPE5,'-',2) ELSE SEM_AFFECT_TYPE5 END
|
|
WHEN t_divers.valeur = 'AFFECT_TYPE6' AND SEM_AFFECT_TYPE3 <> '' THEN CASE WHEN POSITION('-' IN SEM_AFFECT_TYPE6) BETWEEN 4 AND 7 THEN split_part(SEM_AFFECT_TYPE6,'-',2) ELSE SEM_AFFECT_TYPE6 END
|
|
ELSE NULL END,
|
|
chr(1)||'*'))
|
|
AS texte_court
|
|
FROM w_PAISALARIEEMPLOI_ets PAISALARIEEMPLOI
|
|
JOIN rh.t_divers ON t_divers.code = 'SILAE_CODEEMPLOI'
|
|
GROUP BY 2
|
|
;
|
|
|
|
-- 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 precisions du motif d'arret
|
|
|
|
-- Identification des motifs de visite medicale
|
|
|
|
-- 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 sieges d'accident du travail
|
|
|
|
-- Identification des listes de formations
|
|
|
|
-- Sections analytiques
|
|
DROP TABLE IF EXISTS w_PAISALARIEREPANASPE;
|
|
CREATE TEMP TABLE w_PAISALARIEREPANASPE AS
|
|
SELECT *,
|
|
0::bigint AS oid_service,
|
|
''::text AS services,
|
|
''::text AS code_service
|
|
FROM prod_silae.PAISALARIEREPANASPE
|
|
;
|
|
|
|
UPDATE w_PAISALARIEREPANASPE SET
|
|
oid_service = base.cti_to_number(substr(split_part(RAS_AFFECTATION,'-',1),4)),
|
|
code_service = substr(split_part(RAS_AFFECTATION,'-',1),4),
|
|
services = CASE WHEN RAS_AFFECTATION LIKE '%-%' THEN split_part(RAS_AFFECTATION,'-',2) ELSE substr(split_part(RAS_AFFECTATION,'-',1),4) END
|
|
WHERE (
|
|
RAS_AFFECTATION LIKE '%-%' OR
|
|
base.cti_to_number(split_part(RAS_AFFECTATION,'-',1)) > 0
|
|
) AND
|
|
length(split_part(RAS_AFFECTATION,'-',1)) = 6
|
|
;
|
|
|
|
UPDATE w_PAISALARIEREPANASPE SET
|
|
code_service = RAS_AFFECTATION,
|
|
services = RAS_AFFECTATION
|
|
WHERE oid_service = 0
|
|
;
|
|
|
|
ANALYSE w_PAISALARIEREPANASPE
|
|
;
|
|
|
|
INSERT INTO rh.t_section_analytique(code_original, code, texte, texte_court)
|
|
SELECT
|
|
code_service,
|
|
MAX(code_service),
|
|
MAX(services),
|
|
MAX(substr(services, 1, 50))
|
|
FROM w_PAISALARIEREPANASPE
|
|
WHERE oid_service = 0 AND
|
|
code_service <> '' AND
|
|
code_service NOT IN (SELECT CODE_ORIGINAL FROM rh.t_section_analytique WHERE code_original IS NOT NULL)
|
|
GROUP BY 1
|
|
;
|
|
|
|
UPDATE w_PAISALARIEREPANASPE
|
|
SET oid_service = t_section_analytique.oid
|
|
FROM rh.t_section_analytique
|
|
WHERE code_service = code_original
|
|
;
|
|
|
|
DROP TABLE IF EXISTS temp.x_ref_section_analytique
|
|
;
|
|
|
|
CREATE TABLE temp.x_ref_section_analytique AS
|
|
WITH affectation AS (
|
|
SELECT
|
|
oid_service,
|
|
code_service,
|
|
services
|
|
FROM w_PAISALARIEREPANASPE PAISALARIEREPANASPE
|
|
GROUP BY 1,2,3
|
|
)
|
|
SELECT
|
|
oid_service AS oid,
|
|
code_service AS code_original,
|
|
code_service AS code,
|
|
MAX(services) AS texte,
|
|
MAX(services) AS texte_court
|
|
FROM affectation
|
|
GROUP BY 1,2,3
|
|
;
|
|
|
|
-- Identification des rubriques de paie.
|
|
|
|
DROP TABLE IF EXISTS w_hp_0
|
|
;
|
|
|
|
CREATE TEMP TABLE w_hp_0 AS
|
|
SELECT
|
|
PAIBULLETINLIGNE.ctid::text AS cti_ctid,
|
|
BLI_ZONE||'|'||COALESCE(BLI_CODELIBELLE, '-')||'|'||COALESCE(BLI_MARQUE1, '-')||'|'||COALESCE(BLI_MARQUEINTERNE, '-') AS rub,
|
|
ID_PAIBULLETINLIGNE,
|
|
PAIBULLETINLIGNE.ID_PAIBULLETIN,
|
|
BLI_ZONE,
|
|
BLI_CODELIBELLE,
|
|
BLI_LIBELLE,
|
|
BLI_MARQUE1,
|
|
BLI_MARQUEINTERNE,
|
|
BLI_RESULTATS,
|
|
BLI_BASES,
|
|
BLI_BASEP,
|
|
BLI_TAUXOUMONTANTS,
|
|
BLI_TAUXOUMONTANTP,
|
|
BLI_RESULTATP
|
|
FROM prod_silae.PAIBULLETINLIGNE
|
|
JOIN prod_silae.PAIBULLETIN ON PAIBULLETINLIGNE.ID_PAIBULLETIN = PAIBULLETIN.ID_PAIBULLETIN
|
|
JOIN w_PAISALARIEEMPLOI_ets PAISALARIEEMPLOI ON PAIBULLETIN.ID_PAISALARIEEMPLOI = PAISALARIEEMPLOI.ID_PAISALARIEEMPLOI
|
|
WHERE
|
|
(
|
|
BLI_RESULTATS <> 0 OR
|
|
BLI_BASES <> 0 OR
|
|
BLI_BASEP <> 0 OR
|
|
BLI_TAUXOUMONTANTS <> 0 OR
|
|
BLI_TAUXOUMONTANTP <> 0 OR
|
|
BLI_RESULTATP <> 0
|
|
)
|
|
UNION ALL
|
|
SELECT
|
|
'SALBAS|'||PAIBULLETIN.ctid::text AS cti_ctid,
|
|
'2|SALBAS||' AS rub,
|
|
PAIBULLETIN.ID_PAIBULLETIN AS ID_PAIBULLETINLIGNE,
|
|
PAIBULLETIN.ID_PAIBULLETIN,
|
|
2 AS BLI_ZONE,
|
|
'SALBAS'::text AS BLI_CODELIBELLE,
|
|
'Salaire de base'::text AS BLI_LIBELLE,
|
|
''::text AS BLI_MARQUE1,
|
|
''::text AS BLI_MARQUEINTERNE,
|
|
PAIBULLETIN.BUL_SALAIREDEBASE AS BLI_RESULTATS,
|
|
PAIBULLETIN.BUL_NBHC AS BLI_BASES,
|
|
0::numeric AS BLI_BASEP,
|
|
PAIBULLETIN.BUL_TAUXHORAIRE AS BLI_TAUXOUMONTANTS,
|
|
0::numeric AS BLI_TAUXOUMONTANTP,
|
|
0::numeric AS BLI_RESULTATP
|
|
FROM prod_silae.PAIBULLETIN
|
|
JOIN w_PAISALARIEEMPLOI_ets PAISALARIEEMPLOI ON PAIBULLETIN.ID_PAISALARIEEMPLOI = PAISALARIEEMPLOI.ID_PAISALARIEEMPLOI
|
|
UNION ALL
|
|
SELECT
|
|
'TOTHTRAV|'||PAIBULLETIN.ctid::text AS cti_ctid,
|
|
'2|TOTHTRAV||' AS rub,
|
|
PAIBULLETIN.ID_PAIBULLETIN AS ID_PAIBULLETINLIGNE,
|
|
PAIBULLETIN.ID_PAIBULLETIN,
|
|
2 AS BLI_ZONE,
|
|
'TOTHTRAV'::text AS BLI_CODELIBELLE,
|
|
'Total heures travaillees'::text AS BLI_LIBELLE,
|
|
''::text AS BLI_MARQUE1,
|
|
''::text AS BLI_MARQUEINTERNE,
|
|
0::numeric AS BLI_RESULTATS,
|
|
PAIBULLETIN.BUL_NBHMN AS BLI_BASES,
|
|
0::numeric AS BLI_BASEP,
|
|
0::numeric AS BLI_TAUXOUMONTANTS,
|
|
0::numeric AS BLI_TAUXOUMONTANTP,
|
|
0::numeric AS BLI_RESULTATP
|
|
FROM prod_silae.PAIBULLETIN
|
|
JOIN w_PAISALARIEEMPLOI_ets PAISALARIEEMPLOI ON PAIBULLETIN.ID_PAISALARIEEMPLOI = PAISALARIEEMPLOI.ID_PAISALARIEEMPLOI
|
|
UNION ALL
|
|
SELECT
|
|
'BRUT|'||PAIBULLETIN.ctid::text AS cti_ctid,
|
|
'2|BRUT||' AS rub,
|
|
PAIBULLETIN.ID_PAIBULLETIN AS ID_PAIBULLETINLIGNE,
|
|
PAIBULLETIN.ID_PAIBULLETIN,
|
|
2 AS BLI_ZONE,
|
|
'BRUT'::text AS BLI_CODELIBELLE,
|
|
'Salaire Brut'::text AS BLI_LIBELLE,
|
|
''::text AS BLI_MARQUE1,
|
|
''::text AS BLI_MARQUEINTERNE,
|
|
PAIBULLETIN.BUL_BRUT AS BLI_RESULTATS,
|
|
0::numeric AS BLI_BASES,
|
|
0::numeric AS BLI_BASEP,
|
|
0::numeric AS BLI_TAUXOUMONTANTS,
|
|
0::numeric AS BLI_TAUXOUMONTANTP,
|
|
0::numeric AS BLI_RESULTATP
|
|
FROM prod_silae.PAIBULLETIN
|
|
JOIN w_PAISALARIEEMPLOI_ets PAISALARIEEMPLOI ON PAIBULLETIN.ID_PAISALARIEEMPLOI = PAISALARIEEMPLOI.ID_PAISALARIEEMPLOI
|
|
UNION ALL
|
|
SELECT
|
|
'TOTRET|'||PAIBULLETIN.ctid::text AS cti_ctid,
|
|
'3|TOTRET||' AS rub,
|
|
PAIBULLETIN.ID_PAIBULLETIN AS ID_PAIBULLETINLIGNE,
|
|
PAIBULLETIN.ID_PAIBULLETIN,
|
|
3 AS BLI_ZONE,
|
|
'TOTRET'::text AS BLI_CODELIBELLE,
|
|
'Total des retenues'::text AS BLI_LIBELLE,
|
|
''::text AS BLI_MARQUE1,
|
|
''::text AS BLI_MARQUEINTERNE,
|
|
PAIBULLETIN.BUL_CUMULRETENUESSD + PAIBULLETIN.BUL_CUMULRETENUESSND AS BLI_RESULTATS,
|
|
0::numeric AS BLI_BASES,
|
|
0::numeric AS BLI_BASEP,
|
|
0::numeric AS BLI_TAUXOUMONTANTS,
|
|
0::numeric AS BLI_TAUXOUMONTANTP,
|
|
PAIBULLETIN.bul_cumulretenuesp AS BLI_RESULTATP
|
|
FROM prod_silae.PAIBULLETIN
|
|
JOIN w_PAISALARIEEMPLOI_ets PAISALARIEEMPLOI ON PAIBULLETIN.ID_PAISALARIEEMPLOI = PAISALARIEEMPLOI.ID_PAISALARIEEMPLOI
|
|
UNION ALL
|
|
SELECT
|
|
'NETIMP|'||PAIBULLETIN.ctid::text AS cti_ctid,
|
|
'4|NETIMP||' AS rub,
|
|
PAIBULLETIN.ID_PAIBULLETIN AS ID_PAIBULLETINLIGNE,
|
|
PAIBULLETIN.ID_PAIBULLETIN,
|
|
4 AS BLI_ZONE,
|
|
'NETIMP'::text AS BLI_CODELIBELLE,
|
|
'Net Imposable'::text AS BLI_LIBELLE,
|
|
''::text AS BLI_MARQUE1,
|
|
''::text AS BLI_MARQUEINTERNE,
|
|
PAIBULLETIN.BUL_NETIMPOSABLE AS BLI_RESULTATS,
|
|
0::numeric AS BLI_BASES,
|
|
0::numeric AS BLI_BASEP,
|
|
0::numeric AS BLI_TAUXOUMONTANTS,
|
|
0::numeric AS BLI_TAUXOUMONTANTP,
|
|
0::numeric AS BLI_RESULTATP
|
|
FROM prod_silae.PAIBULLETIN
|
|
JOIN w_PAISALARIEEMPLOI_ets PAISALARIEEMPLOI ON PAIBULLETIN.ID_PAISALARIEEMPLOI = PAISALARIEEMPLOI.ID_PAISALARIEEMPLOI
|
|
UNION ALL
|
|
SELECT
|
|
'NETAPAYER|'||PAIBULLETIN.ctid::text AS cti_ctid,
|
|
'4|NETAPAYER||' AS rub,
|
|
PAIBULLETIN.ID_PAIBULLETIN AS ID_PAIBULLETINLIGNE,
|
|
PAIBULLETIN.ID_PAIBULLETIN,
|
|
4 AS BLI_ZONE,
|
|
'NETAPAYER'::text AS BLI_CODELIBELLE,
|
|
'Net a Payer'::text AS BLI_LIBELLE,
|
|
''::text AS BLI_MARQUE1,
|
|
''::text AS BLI_MARQUEINTERNE,
|
|
PAIBULLETIN.BUL_NETAPAYER AS BLI_RESULTATS,
|
|
0::numeric AS BLI_BASES,
|
|
0::numeric AS BLI_BASEP,
|
|
0::numeric AS BLI_TAUXOUMONTANTS,
|
|
0::numeric AS BLI_TAUXOUMONTANTP,
|
|
0::numeric AS BLI_RESULTATP
|
|
FROM prod_silae.PAIBULLETIN
|
|
JOIN w_PAISALARIEEMPLOI_ets PAISALARIEEMPLOI ON PAIBULLETIN.ID_PAISALARIEEMPLOI = PAISALARIEEMPLOI.ID_PAISALARIEEMPLOI
|
|
;
|
|
ANALYSE w_hp_0
|
|
;
|
|
|
|
-- Formatage rubrique selon texte
|
|
DROP TABLE IF EXISTS w_hp_0_rub;
|
|
CREATE TEMP TABLE w_hp_0_rub AS
|
|
SELECT BLI_ZONE,
|
|
BLI_CODELIBELLE,
|
|
BLI_LIBELLE,
|
|
trim(replace(BLI_LIBELLE,' ',' ')) AS texte,
|
|
''::text AS texte_maj,
|
|
''::text AS code,
|
|
''::text AS code_original,
|
|
count(*) AS nb
|
|
FROM w_hp_0
|
|
JOIN rh.t_divers ON t_divers.code = 'SILAE_RUBRIQUE'
|
|
WHERE t_divers.valeur = '2'
|
|
GROUP BY 1,2,3
|
|
;
|
|
|
|
UPDATE w_hp_0_rub
|
|
SET texte = trim(left(texte,
|
|
LEAST(
|
|
CASE WHEN position('(' IN texte) > 5 THEN position('(' IN texte)-1 ELSE 999 END,
|
|
CASE WHEN position('0' IN texte) > 5 THEN position('0' IN texte)-1 ELSE 999 END,
|
|
CASE WHEN position('1' IN texte) > 5 THEN position('1' IN texte)-1 ELSE 999 END,
|
|
CASE WHEN position('2' IN texte) > 5 THEN position('2' IN texte)-1 ELSE 999 END,
|
|
CASE WHEN position('3' IN texte) > 5 THEN position('3' IN texte)-1 ELSE 999 END,
|
|
CASE WHEN position('4' IN texte) > 5 THEN position('4' IN texte)-1 ELSE 999 END,
|
|
CASE WHEN position('5' IN texte) > 5 THEN position('5' IN texte)-1 ELSE 999 END,
|
|
CASE WHEN position('6' IN texte) > 5 THEN position('6' IN texte)-1 ELSE 999 END,
|
|
CASE WHEN position('7' IN texte) > 5 THEN position('7' IN texte)-1 ELSE 999 END,
|
|
CASE WHEN position('8' IN texte) > 5 THEN position('8' IN texte)-1 ELSE 999 END,
|
|
CASE WHEN position('9' IN texte) > 5 THEN position('9' IN texte)-1 ELSE 999 END,
|
|
CASE WHEN position('Acompte d' IN texte) > 0 THEN position('Acompte de' IN texte)+6 ELSE 999 END,
|
|
CASE WHEN position(' jan' IN lower(texte)) > 0 THEN position(' jan' IN lower(texte))-1 ELSE 999 END,
|
|
CASE WHEN position(' fév' IN lower(texte)) > 0 THEN position(' fév' IN lower(texte))-1 ELSE 999 END,
|
|
CASE WHEN position(' mars' IN lower(texte)) > 0 THEN position(' mars' IN lower(texte))-1 ELSE 999 END,
|
|
CASE WHEN position(' avr' IN lower(texte)) > 0 THEN position(' avr' IN lower(texte))-1 ELSE 999 END,
|
|
CASE WHEN position(' mai' IN lower(texte)) > 0 THEN position(' mai' IN lower(texte))-1 ELSE 999 END,
|
|
CASE WHEN position(' juin' IN lower(texte)) > 0 THEN position(' juin' IN lower(texte))-1 ELSE 999 END,
|
|
CASE WHEN position(' juil' IN lower(texte)) > 0 THEN position(' juil' IN lower(texte))-1 ELSE 999 END,
|
|
CASE WHEN position(' aout' IN lower(texte)) > 0 THEN position(' aout' IN lower(texte))-1 ELSE 999 END,
|
|
CASE WHEN position(' sept' IN lower(texte)) > 0 THEN position(' sept' IN lower(texte))-1 ELSE 999 END,
|
|
CASE WHEN position(' oct' IN lower(texte)) > 0 THEN position(' oct' IN lower(texte))-1 ELSE 999 END,
|
|
CASE WHEN position(' nov' IN lower(texte)) > 0 THEN position(' nov' IN lower(texte))-1 ELSE 999 END,
|
|
CASE WHEN position(' déc' IN lower(texte)) > 0 THEN position(' déc' IN lower(texte))-1 ELSE 999 END
|
|
)))
|
|
WHERE texte like '%0%' OR
|
|
texte like '%(%' OR
|
|
texte like '%1%' OR
|
|
texte like '%2%' OR
|
|
texte like '%3%' OR
|
|
texte like '%4%' OR
|
|
texte like '%5%' OR
|
|
texte like '%6%' OR
|
|
texte like '%7%' OR
|
|
texte like '%8%' OR
|
|
texte like '%9%' OR
|
|
texte like '%Acompte d%' OR
|
|
texte ilike '% jan%' OR
|
|
texte ilike '% fév%' OR
|
|
texte ilike '% mars%' OR
|
|
texte ilike '% avr%' OR
|
|
texte ilike '% mai%' OR
|
|
texte ilike '% juin%' OR
|
|
texte ilike '% juil' OR
|
|
texte ilike '% aout%' OR
|
|
texte ilike '% sept%' OR
|
|
texte ilike '% oct%' OR
|
|
texte ilike '% nov%' OR
|
|
texte ilike '% déc%'
|
|
;
|
|
|
|
UPDATE w_hp_0_rub
|
|
SET texte = trim(left(texte,length(texte)-3))
|
|
WHERE texte ilike '% du' OR texte ilike '% de'
|
|
;
|
|
|
|
UPDATE w_hp_0_rub
|
|
SET texte_maj = translate(upper(base.cti_remove_accent(texte)),'.:/-+''','')
|
|
;
|
|
|
|
UPDATE w_hp_0_rub SET
|
|
code_original = BLI_ZONE ||
|
|
COALESCE(BLI_CODELIBELLE,'ZZZ') ||
|
|
CASE WHEN COALESCE(BLI_CODELIBELLE,'') NOT IN ('SALBAS','TOTHTRAV','BRUT','TOTRET','NETIMP','NETAPAYER')
|
|
THEN translate(texte_maj,' ','')
|
|
ELSE ''
|
|
END,
|
|
code = BLI_ZONE ||
|
|
COALESCE(BLI_CODELIBELLE,'ZZZ') ||
|
|
CASE WHEN COALESCE(BLI_CODELIBELLE,'') NOT IN ('SALBAS','TOTHTRAV','BRUT','TOTRET','NETIMP','NETAPAYER')
|
|
THEN
|
|
substr(split_part(texte_maj,' ',1),1,3) ||
|
|
substr(split_part(texte_maj,' ',2),1,3) ||
|
|
substr(split_part(texte_maj,' ',3),1,3) ||
|
|
substr(split_part(texte_maj,' ',4),1,3) ||
|
|
substr(split_part(texte_maj,' ',5),1,3)
|
|
ELSE ''
|
|
END
|
|
;
|
|
|
|
ANALYSE w_hp_0_rub
|
|
;
|
|
|
|
UPDATE w_hp_0 SET
|
|
rub = code_original
|
|
FROM w_hp_0_rub
|
|
WHERE w_hp_0.BLI_ZONE = w_hp_0_rub.BLI_ZONE AND
|
|
COALESCE(w_hp_0.BLI_CODELIBELLE,'') = COALESCE(w_hp_0_rub.BLI_CODELIBELLE,'') AND
|
|
w_hp_0.BLI_LIBELLE = w_hp_0_rub.BLI_LIBELLE
|
|
;
|
|
|
|
DROP TABLE IF EXISTS w_rubriques_2;
|
|
CREATE TEMP TABLE w_rubriques_2 AS
|
|
SELECT code_original, (max(ARRAY[to_char(nb,'FM00000000'),texte]))[2] AS texte, (max(ARRAY[to_char(nb,'FM00000000'),code]))[2] AS code
|
|
FROM
|
|
(
|
|
SELECT code_original, texte, code, sum(nb) AS nb
|
|
FROM w_hp_0_rub
|
|
GROUP BY 1,2,3
|
|
) subview
|
|
GROUP BY 1
|
|
;
|
|
|
|
ANALYSE w_rubriques_2
|
|
;
|
|
|
|
|
|
-- Table des rubriques
|
|
DROP TABLE IF EXISTS temp.x_ref_rubrique
|
|
;
|
|
|
|
CREATE TABLE temp.x_ref_rubrique AS
|
|
WITH rub_det_1 AS (
|
|
SELECT
|
|
rub,
|
|
(MAX(ARRAY[to_char(ID_PAIBULLETINLIGNE,'FM000000000000000'),BLI_LIBELLE]))[2] AS texte,
|
|
BLI_ZONE IN (2, 3, 4) AS p_detail,
|
|
BLI_ZONE IN (2, 3, 4) AS p_nombre,
|
|
BLI_ZONE IN (2, 3, 4) AS p_base,
|
|
false AS p_heures_contrat,
|
|
false AS p_heures_payees,
|
|
false AS p_heures_travaillees,
|
|
rub between 'B000' and 'B999' or rub between 'C100' and 'C999' AS p_masse_salariale,
|
|
BLI_ZONE = 2 AS p_brut,
|
|
false AS p_avantage_nature,
|
|
false AS p_frais_imposables,
|
|
BLI_ZONE = 3 AS p_cotisation_salarie,
|
|
BLI_ZONE = 3 AS p_cotisation_patronale,
|
|
BLI_ZONE = 4 AS p_od_net_salarie,
|
|
false AS p_od_net_patronale,
|
|
BLI_ZONE IN (2, 3) OR (BLI_ZONE = 4 AND substr(BLI_CODELIBELLE, 1, 1) NOT IN ('K', 'F', 'B', 'A', 'J')) AS p_net_imposable,
|
|
BLI_ZONE IN (2, 3, 4) AS p_net_a_payer
|
|
FROM w_hp_0
|
|
WHERE rub != '4|K07|-|PAS'
|
|
GROUP BY 1,3,4,5,6,7,8,9,10,11,12,13,14,15,16,17,18
|
|
)
|
|
SELECT
|
|
rub AS code_original,
|
|
COALESCE(w_rubriques_2.code,rub) AS code,
|
|
COALESCE(w_rubriques_2.texte,rub_det_1.texte) AS texte,
|
|
null::text AS texte_court,
|
|
-1 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,
|
|
p_heures_contrat 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,
|
|
1 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,
|
|
case when p_cotisation_salarie then -1 else 1 end AS c_net_imposable,
|
|
p_net_a_payer AS p_net_a_payer,
|
|
3 AS s_net_a_payer,
|
|
case when p_cotisation_salarie then -1 else 1 end AS c_net_a_payer
|
|
FROM rub_det_1
|
|
LEFT JOIN w_rubriques_2 ON rub = w_rubriques_2.code_original
|
|
;
|
|
|
|
]]></sqlcmd>
|
|
</NODE>
|
|
<NODE label="Pre-traitements">
|
|
<sqlcmd><![CDATA[
|
|
|
|
-- ALIMENTATION DES HISTORIQUES
|
|
|
|
DROP TABLE IF EXISTS w_sal_exc
|
|
;
|
|
|
|
CREATE TEMP TABLE w_sal_exc AS
|
|
SELECT
|
|
ID_PAISALARIE AS exc_ID_PAISALARIE
|
|
FROM prod_silae.PAISALARIE
|
|
JOIN prod_silae.INTERVENANT ON INTERVENANT.ID_INTERVENANT = PAISALARIE.ID_INTERVENANT
|
|
WHERE INT_NOMUSUEL !~ '^A[0-9]' -- Ne pas prendre les matricules correspondant a des "modeles" . Exemple : 'A0 MODELE IDE'.
|
|
;
|
|
|
|
-- SALARIES
|
|
DROP TABLE IF EXISTS temp.x_ref_salarie
|
|
;
|
|
|
|
CREATE TABLE temp.x_ref_salarie AS
|
|
WITH toto AS (
|
|
SELECT
|
|
ID_PAISALARIE,
|
|
max(ID_PAIETABLISSEMENT) AS entreprise
|
|
FROM w_PAISALARIEEMPLOI_ets PAISALARIEEMPLOI
|
|
GROUP BY 1
|
|
)
|
|
SELECT
|
|
rhp('finess') AS finess,
|
|
INT_NOMUSUEL AS nom,
|
|
INT_PRENOM AS prenom,
|
|
COALESCE(INT_DATENAISSANCE::date, '1970-01-01'::date) AS date_naissance,
|
|
CASE WHEN INT_CIVILITE = 1
|
|
THEN 'M'
|
|
ELSE 'F'
|
|
END AS sexe,
|
|
SAL_S30_G10_05_001 AS matricule,
|
|
'' AS matricule_planning,
|
|
SAL_S30_G10_05_001 AS code,
|
|
PAISALARIE.ID_PAISALARIE AS code_original,
|
|
-- COALESCE(toto.entreprise_id, 0) AS entreprise_id,
|
|
entreprise,
|
|
-- COALESCE(t_nationalites.oid, 0) AS nationalite_id,
|
|
INTERVENANT.INT_PAYSNATIONALITEISO AS nationalite,
|
|
-- COALESCE(t_codes_postaux.oid, 0) AS code_postal_id,
|
|
INT_CODEPOSTAL::text AS code_postal,
|
|
INT_NOMNAISSANCE AS nom_naissance,
|
|
-- COALESCE(t_situations_famille.oid, 0) AS situation_famille_id, -- INT_SITUATIONFAMILIALE
|
|
INTERVENANT.INT_SITUATIONFAMILIALE AS situation_famille,
|
|
INT_NUMEROSS AS nir,
|
|
null::date AS date_debut, -- utilise pour la partie "Dernier contrat" du detail salarie
|
|
null::date AS date_fin, -- utilise pour la partie "Dernier contrat" du detail salarie
|
|
null::date AS date_entree_ets, -- sal_dateentree
|
|
null::date AS date_sortie_ets, -- sal_datesortie SAL_DATEANCIENNETE SAL_DATEANCIENNETEdepart
|
|
SAL_DATEANCIENNETE::date AS date_anciennete,
|
|
-- Champs dedies 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,
|
|
''::text AS adresse1,
|
|
''::text AS adresse2
|
|
FROM prod_silae.PAISALARIE
|
|
JOIN prod_silae.INTERVENANT ON INTERVENANT.ID_INTERVENANT = PAISALARIE.ID_INTERVENANT
|
|
JOIN toto ON toto.ID_PAISALARIE = PAISALARIE.ID_PAISALARIE
|
|
JOIN w_sal_exc ON w_sal_exc.exc_ID_PAISALARIE = PAISALARIE.ID_PAISALARIE
|
|
-- left JOIN rh.t_codes_postaux ON t_codes_postaux.code = INT_CODEPOSTAL
|
|
-- left JOIN rh.t_nationalites ON t_nationalites.code_original = INTERVENANT.INT_PAYSNATIONALITEISO
|
|
-- left JOIN rh.t_situations_famille ON t_situations_famille.code_original = INTERVENANT.INT_SITUATIONFAMILIALE
|
|
;
|
|
|
|
-- HISTORIQUE DES CONTRATS.
|
|
DROP TABLE IF EXISTS temp.x_hst_contrat
|
|
;
|
|
|
|
CREATE TABLE temp.x_hst_contrat AS
|
|
WITH last_data AS (
|
|
SELECT
|
|
ID_PAISALARIE AS last_sal_gp,
|
|
COALESCE(sem_dtdebcontrat, sem_dtdeb)::date AS last_date_gp,
|
|
(max(array[extract(epoch FROM COALESCE(SEm_DATEARCHIVE, '00010101'::date)), ID_PAISALARIEEMPLOI]))[2] AS ID_PAISALARIEEMPLOI_gp
|
|
FROM w_PAISALARIEEMPLOI_ets PAISALARIEEMPLOI
|
|
GROUP BY 1,2
|
|
)
|
|
SELECT
|
|
row_number() over () AS row_id,
|
|
CLI_NUMERODOSSIER AS ent_code_original,
|
|
ID_PAIETABLISSEMENT2 AS ets_code_original,
|
|
CLI_NUMERODOSSIER||'-'||ID_PAIETABLISSEMENT2 AS ety_code_original,
|
|
ID_PAISALARIE::text AS sal_code_original,
|
|
PAISALARIEEMPLOI.ID_PAISALARIEEMPLOI::text AS cnt_code_original,
|
|
PAISALARIEEMPLOI.ID_PAISALARIEEMPLOI AS numero_contrat,
|
|
COALESCE(sem_dtdebcontrat, sem_dtdeb, '1970-01-01'::date)::date AS date_debut,
|
|
COALESCE(sem_dtfin::date, lead(COALESCE(sem_dtdebcontrat, sem_dtdeb)) over (partition by PAISALARIEEMPLOI.ID_PAISALARIE order by COALESCE(sem_dtdebcontrat, sem_dtdeb)) - '1 day'::interval, '20991231'::date)::date AS date_fin,
|
|
COALESCE(lower(SEM_S41_G01_00_011_001), chr(1)||'*') AS categorie_socio_professionnelle_code_original,
|
|
COALESCE(SEM_CDDMOTIF, chr(1)||'*') AS motif_debut_code_original,
|
|
COALESCE(SEM_MOTIFRUPTURECONTRAT, chr(1)||'*') AS motif_fin_code_original,
|
|
COALESCE(replace(SEM_S41_G01_00_010::text,' ','_'), chr(1)||'*') AS qualification_code_original,
|
|
COALESCE(SEM_S41_G01_00_014, chr(1)||'*') AS statut_code_original,
|
|
COALESCE(SEM_S41_G01_00_012_001, chr(1)||'*') AS type_contrat_code_original,
|
|
COALESCE(nullif(SEM_HORAIREMENSUEL, 0), 151.67)::text AS type_temps_travail_code_original,
|
|
COALESCE(CASE
|
|
WHEN t_divers_SILAE_SERVICE.valeur = 'AFFECT_TYPE1' THEN SEM_AFFECT_TYPE1
|
|
WHEN t_divers_SILAE_SERVICE.valeur = 'AFFECT_TYPE2' THEN SEM_AFFECT_TYPE2
|
|
WHEN t_divers_SILAE_SERVICE.valeur = 'AFFECT_TYPE3' THEN SEM_AFFECT_TYPE3
|
|
WHEN t_divers_SILAE_SERVICE.valeur = 'AFFECT_TYPE4' THEN SEM_AFFECT_TYPE4
|
|
WHEN t_divers_SILAE_SERVICE.valeur = 'AFFECT_TYPE5' THEN SEM_AFFECT_TYPE5
|
|
WHEN t_divers_SILAE_SERVICE.valeur = 'AFFECT_TYPE6' THEN SEM_AFFECT_TYPE6
|
|
ELSE NULL END , chr(1)||'*')
|
|
AS service_code_original,
|
|
COALESCE(CASE
|
|
WHEN t_divers_SILAE_CODEEMPLOI.valeur = 'AFFECT_TYPE1' THEN SEM_AFFECT_TYPE1
|
|
WHEN t_divers_SILAE_CODEEMPLOI.valeur = 'AFFECT_TYPE2' THEN SEM_AFFECT_TYPE2
|
|
WHEN t_divers_SILAE_CODEEMPLOI.valeur = 'AFFECT_TYPE3' THEN SEM_AFFECT_TYPE3
|
|
WHEN t_divers_SILAE_CODEEMPLOI.valeur = 'AFFECT_TYPE4' THEN SEM_AFFECT_TYPE4
|
|
WHEN t_divers_SILAE_CODEEMPLOI.valeur = 'AFFECT_TYPE5' THEN SEM_AFFECT_TYPE5
|
|
WHEN t_divers_SILAE_CODEEMPLOI.valeur = 'AFFECT_TYPE6' THEN SEM_AFFECT_TYPE6
|
|
ELSE NULL END , chr(1)||'*')
|
|
AS code_emploi_code_original,
|
|
COALESCE(CASE
|
|
WHEN t_divers_SILAE_SPECIALITE.valeur = 'AFFECT_TYPE1' THEN SEM_AFFECT_TYPE1
|
|
WHEN t_divers_SILAE_SPECIALITE.valeur = 'AFFECT_TYPE2' THEN SEM_AFFECT_TYPE2
|
|
WHEN t_divers_SILAE_SPECIALITE.valeur = 'AFFECT_TYPE3' THEN SEM_AFFECT_TYPE3
|
|
WHEN t_divers_SILAE_SPECIALITE.valeur = 'AFFECT_TYPE4' THEN SEM_AFFECT_TYPE4
|
|
WHEN t_divers_SILAE_SPECIALITE.valeur = 'AFFECT_TYPE5' THEN SEM_AFFECT_TYPE5
|
|
WHEN t_divers_SILAE_SPECIALITE.valeur = 'AFFECT_TYPE6' THEN SEM_AFFECT_TYPE6
|
|
ELSE NULL END , chr(1)||'*')
|
|
AS specialite_code_original,
|
|
COALESCE(nullif(SEM_HORAIREMENSUEL, 0), 151.67) / 151.67 AS etp_contrat
|
|
FROM w_PAISALARIEEMPLOI_ets PAISALARIEEMPLOI
|
|
JOIN last_data ON last_data.ID_PAISALARIEEMPLOI_gp = PAISALARIEEMPLOI.ID_PAISALARIEEMPLOI
|
|
JOIN w_sal_exc ON w_sal_exc.exc_ID_PAISALARIE = PAISALARIEEMPLOI.ID_PAISALARIE
|
|
JOIN rh.t_divers t_divers_SILAE_SERVICE ON t_divers_SILAE_SERVICE.code = 'SILAE_SERVICE'
|
|
JOIN rh.t_divers t_divers_SILAE_CODEEMPLOI ON t_divers_SILAE_CODEEMPLOI.code = 'SILAE_CODEEMPLOI'
|
|
JOIN rh.t_divers t_divers_SILAE_SPECIALITE ON t_divers_SILAE_SPECIALITE.code = 'SILAE_SPECIALITE'
|
|
;
|
|
|
|
WITH dates_es AS (
|
|
SELECT
|
|
sal_code_original,
|
|
max(date_debut) AS cn_date_debut,
|
|
max(date_fin) AS cn_date_fin,
|
|
min(date_debut) AS es_date_debut,
|
|
max(date_fin) AS es_date_fin
|
|
FROM temp.x_hst_contrat
|
|
GROUP BY 1
|
|
)
|
|
UPDATE temp.x_ref_salarie SET
|
|
date_debut = dates_es.cn_date_debut,
|
|
date_fin = dates_es.cn_date_fin,
|
|
date_entree_ets = dates_es.es_date_debut,
|
|
date_sortie_ets = dates_es.es_date_fin
|
|
FROM dates_es
|
|
WHERE x_ref_salarie.code_original = dates_es.sal_code_original
|
|
;
|
|
|
|
WITH dates_anc AS (
|
|
SELECT
|
|
sal_code_original,
|
|
min(date_debut) AS date_debut
|
|
FROM temp.x_hst_contrat
|
|
GROUP BY 1
|
|
)
|
|
UPDATE temp.x_ref_salarie SET
|
|
date_anciennete = dates_anc.date_debut
|
|
FROM dates_anc
|
|
WHERE 1=1
|
|
and x_ref_salarie.code_original = dates_anc.sal_code_original
|
|
and x_ref_salarie.date_anciennete is null
|
|
;
|
|
|
|
-- HISTORIQUE DES BULLETINS.
|
|
DROP TABLE IF EXISTS w_cnt_trans
|
|
;
|
|
|
|
CREATE TEMP TABLE w_cnt_trans AS
|
|
WITH toto AS (
|
|
SELECT
|
|
ID_PAIETABLISSEMENT2 AS ID_PAIETABLISSEMENT,
|
|
ID_PAISALARIE AS last_sal_gp,
|
|
COALESCE(sem_dtdebcontrat, sem_dtdeb)::date AS last_date_gp,
|
|
(max(array[extract(epoch FROM COALESCE(SEm_DATEARCHIVE, '00010101'::date)), ID_PAISALARIEEMPLOI]))[2] AS cnt_ori,
|
|
ARRAY_AGG(ID_PAISALARIEEMPLOI) AS agg_ID_PAISALARIEEMPLOI
|
|
FROM w_PAISALARIEEMPLOI_ets PAISALARIEEMPLOI
|
|
JOIN w_sal_exc ON w_sal_exc.exc_ID_PAISALARIE = PAISALARIEEMPLOI.ID_PAISALARIE
|
|
GROUP BY 1,2,3)
|
|
SELECT
|
|
ID_PAIETABLISSEMENT,
|
|
cnt_ori,
|
|
UNNEST(agg_ID_PAISALARIEEMPLOI) AS ID_PAISALARIEEMPLOI_trans
|
|
FROM toto
|
|
;
|
|
|
|
DROP TABLE IF EXISTS w_hp_1
|
|
;
|
|
|
|
CREATE TEMP TABLE w_hp_1 AS
|
|
SELECT
|
|
-- row_number() OVER (partition by PAIBULLETIN.ID_PAIBULLETIN ORDER BY PAIBULLETINLIGNE.cti_ctid) AS bul_code_original,
|
|
PAIBULLETIN.ID_PAIBULLETIN AS bul_code_original,
|
|
-- row_number() OVER (ORDER BY PAIBULLETINLIGNE.cti_ctid) AS ligne_code_original,
|
|
PAIBULLETINLIGNE.ID_PAIBULLETINLIGNE AS ligne_code_original,
|
|
w_cnt_trans.ID_PAIETABLISSEMENT AS ets_code_original,
|
|
w_ets.CLI_NUMERODOSSIER AS ent_code_original,
|
|
w_ets.CLI_NUMERODOSSIER||'-'||w_ets.ID_PAIETABLISSEMENT2 AS ety_code_original,
|
|
PAIBULLETIN.ID_PAIBULLETIN,
|
|
PAIBULLETINLIGNE.ID_PAIBULLETINLIGNE,
|
|
PAIBULLETIN.ID_PAISALARIE,
|
|
PAIBULLETIN.ID_PAISALARIEEMPLOI,
|
|
w_cnt_trans.cnt_ori,
|
|
BUL_PERIODE::date AS date_paie,
|
|
to_char(BUL_PERIODE , 'YYYYMM')::int AS mois_paie,
|
|
rub AS rub_code,
|
|
case when BLI_BASES = 0 then BLI_BASEP else BLI_BASES end AS base,
|
|
BLI_TAUXOUMONTANTS AS txsal,
|
|
BLI_RESULTATS AS mntsal,
|
|
BLI_TAUXOUMONTANTP AS txpat,
|
|
BLI_RESULTATP AS mntpat
|
|
FROM w_hp_0 AS PAIBULLETINLIGNE
|
|
JOIN prod_silae.PAIBULLETIN ON PAIBULLETIN.ID_PAIBULLETIN = PAIBULLETINLIGNE.ID_PAIBULLETIN
|
|
JOIN w_cnt_trans ON w_cnt_trans.ID_PAISALARIEEMPLOI_trans = PAIBULLETIN.ID_PAISALARIEEMPLOI
|
|
JOIN w_ets ON w_ets.ID_PAIETABLISSEMENT = w_cnt_trans.ID_PAIETABLISSEMENT
|
|
;
|
|
|
|
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,
|
|
ID_PAISALARIE::text AS sal_code_original,
|
|
bul_code_original,
|
|
base.cti_first_day(date_paie) AS date_debut,
|
|
base.cti_last_day(date_paie) AS date_fin,
|
|
date_paie,
|
|
mois_paie AS mois_paie,
|
|
ligne_code_original AS row_id,
|
|
bul_code_original AS bul_id,
|
|
null::text AS cnt_code_original, -- un bulletin est rattache a un seul et unique contrat.
|
|
0 AS est_hors_periode,
|
|
rub_code,
|
|
base,
|
|
txsal,
|
|
mntsal,
|
|
txpat,
|
|
mntpat
|
|
FROM w_hp_1
|
|
;
|
|
|
|
-- Association avec le contrat correspondant aux dates.
|
|
-- Un bulletin est rattache a 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 precedent.
|
|
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 renseigne.
|
|
-- A remonter plus tard dans une table speciale avant suppression pour controle expert.
|
|
delete FROM temp.x_hst_bulletin
|
|
WHERE cnt_code_original is null
|
|
;
|
|
|
|
-- HISTORIQUE ETP Theorique contrat.
|
|
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_debut AS date_effet,
|
|
etp_contrat
|
|
FROM temp.x_hst_contrat
|
|
GROUP BY 1,2,3,4,5
|
|
;
|
|
|
|
-- HISTORIQUE CSP.
|
|
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_debut AS date_effet,
|
|
categorie_socio_professionnelle_code_original
|
|
FROM temp.x_hst_contrat
|
|
GROUP BY 1,2,3,4,5
|
|
|
|
;
|
|
|
|
-- HISTORIQUE Motif de debut.
|
|
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_debut AS date_effet,
|
|
motif_debut_code_original
|
|
FROM temp.x_hst_contrat
|
|
GROUP BY 1,2,3,4,5
|
|
;
|
|
|
|
-- HISTORIQUE Motif de fin.
|
|
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_debut AS date_effet,
|
|
motif_fin_code_original
|
|
FROM temp.x_hst_contrat
|
|
GROUP BY 1,2,3,4,5
|
|
|
|
;
|
|
|
|
-- HISTORIQUE Types de contrat.
|
|
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_debut AS date_effet,
|
|
type_contrat_code_original
|
|
FROM temp.x_hst_contrat
|
|
GROUP BY 1,2,3,4,5
|
|
;
|
|
|
|
-- HISTORIQUE CSP.
|
|
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_debut AS date_effet,
|
|
qualification_code_original
|
|
FROM temp.x_hst_contrat
|
|
GROUP BY 1,2,3,4,5
|
|
;
|
|
|
|
-- HISTORIQUE Statut.
|
|
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_debut AS date_effet,
|
|
statut_code_original
|
|
FROM temp.x_hst_contrat
|
|
GROUP BY 1,2,3,4,5
|
|
;
|
|
|
|
-- HISTORIQUE CSP.
|
|
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_debut AS date_effet,
|
|
type_temps_travail_code_original
|
|
FROM temp.x_hst_contrat
|
|
GROUP BY 1,2,3,4,5
|
|
;
|
|
|
|
-- HISTORIQUE CSP.
|
|
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_debut AS date_effet,
|
|
service_code_original
|
|
FROM temp.x_hst_contrat
|
|
GROUP BY 1,2,3,4,5
|
|
;
|
|
|
|
-- HISTORIQUE CSP.
|
|
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_debut AS date_effet,
|
|
code_emploi_code_original
|
|
FROM temp.x_hst_contrat
|
|
GROUP BY 1,2,3,4,5
|
|
;
|
|
|
|
-- HISTORIQUE CSP.
|
|
DROP TABLE IF EXISTS temp.x_hst_specialite
|
|
;
|
|
|
|
CREATE TABLE temp.x_hst_specialite AS
|
|
SELECT
|
|
ety_code_original,
|
|
sal_code_original,
|
|
cnt_code_original,
|
|
date_debut AS date_effet,
|
|
specialite_code_original
|
|
FROM temp.x_hst_contrat
|
|
GROUP BY 1,2,3,4,5
|
|
;
|
|
|
|
-- 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
|
|
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,
|
|
rub_code AS rub_code_original,
|
|
''::text AS cpt_code_original,
|
|
base,
|
|
txsal,
|
|
mntsal,
|
|
txpat,
|
|
mntpat
|
|
FROM temp.x_hst_bulletin AS bulletins
|
|
JOIN temp.x_ref_ets ON x_ref_ets.ety_code_original = bulletins.ety_code_original
|
|
WHERE 1=1
|
|
AND bulletins.mois_paie >= to_char(rhp('rhprovider_start')::date, 'YYYYMM')
|
|
;
|
|
]]></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 periode AS (
|
|
SELECT
|
|
ID_PAISALARIE,
|
|
ras_dtdebvalidite AS date_debut,
|
|
COALESCE(lead(ras_dtdebvalidite) OVER(partition by ID_PAISALARIE ORDER BY ras_dtdebvalidite),'20991231') - interval '1 day' AS date_fin
|
|
FROM prod_silae.PAISALARIEREPANASPE
|
|
WHERE ras_dtdebvalidite is not null
|
|
GROUP BY 1,2
|
|
)
|
|
, base AS (
|
|
SELECT
|
|
id_PAISALARIEREPANASPE,
|
|
PAISALARIEREPANASPE.ID_PAISALARIE,
|
|
ras_pcent,
|
|
split_part(ras_affectation,'-',1) AS affectation,
|
|
ras_dtdebvalidite AS date_debut,
|
|
periode.date_fin
|
|
FROM prod_silae.PAISALARIEREPANASPE
|
|
JOIN periode ON 1 = 1
|
|
and periode.ID_PAISALARIE = PAISALARIEREPANASPE.ID_PAISALARIE
|
|
and periode.date_debut = PAISALARIEREPANASPE.ras_dtdebvalidite
|
|
GROUP BY 1,2,3,4,5,6
|
|
)
|
|
SELECT
|
|
x_hst_bulletin.bul_id,
|
|
substr(affectation, 4) AS section_analytique_id,
|
|
substr(affectation, 4) AS section_analytique_code_original,
|
|
base.cti_division(ras_pcent, 100) AS ratio
|
|
FROM temp.x_hst_bulletin
|
|
JOIN base ON 1 = 1
|
|
and x_hst_bulletin.sal_code_original = base.ID_PAISALARIE
|
|
and x_hst_bulletin.sal_code_original = base.ID_PAISALARIE
|
|
WHERE date_paie between base.date_debut and base.date_fin
|
|
GROUP BY 1,2,3,4
|
|
;
|
|
|
|
]]></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="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>
|