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.
 
 
 

255 lines
16 KiB

<?xml version="1.0" encoding="ISO-8859-1"?>
<VUE name="RH000120" label="RH-Paie. Index Egapro" title="= 'Index Egapro (' + SELECT.PERIODE_LABEL + ' à ' + SELECT.TOPERIODE_LABEL + ')'" database="iCTI" swf="*CTI_view1" globals="RH_globals.XML" componentsFile="RH_components.XML" softCode="iCTI_rh">
<CACHE cachable="false" />
<SELECTIONS label="Paramètres de l'analyse" displayText="">
<GROUP label="Période">
<FIELD name="ALIAS_PERIODE" label="" UI="combo" width="220" default="CUM_LAST_MONTH" tree="true" globalListProvider="ALIAS_PERIODE" />
<FIELD name="PERIODE" label="" UI="combo" tree="true" width="200" default="2019-01-01" globalListProvider="PERIODE_DEBUT" />
<FIELD name="TOPERIODE" label="au" UI="combo" tree="true" width="200" default="2019-12-31" globalListProvider="PERIODE_FIN" />
</GROUP>
<GROUP label="Établissement">
<FIELD name="ETABLISSEMENT" label="" UI="combo" width="300" tree="true" default="-1" globalListProvider="ETABLISSEMENTS" showIfNotDefault="true" />
</GROUP>
</SELECTIONS>
<QUERIES>
<QUERY label="Égalité professionnelle">
<SQL>
<select><![CDATA[
insert into rh.t_divers (code, texte, valeur)
select 'EGAPRO_STAT', 'Statut pour Index Egapro.', 'VED_STATUT'
where
(select count(*) = 0 from rh.t_divers where code = 'EGAPRO_STAT')
;
DROP TABLE IF EXISTS sal_info_base
;
CREATE TEMP TABLE sal_info_base AS
select
salarie_id,
salarie_code,
sexe_code,
floor(((substr(mois_activite_id::text, 1, 4)||'1231')::date - (substr(mois_activite_id::text, 1, 4)||'0101')::date + 1.0) / 2.0) as nb_j_min,
--type_contrat_texte, --type_contrat_code,
--statut_texte,
sum((date_fin_activite - date_debut_activite + 1) * ratio) as nb_j_contract,
(max(array[date_fin_activite::text, type_contrat_texte]))[2] as type_contrat_local,
(max(array[date_fin_activite::text, type_contrat_section_code[(select sequence from rh.t_classes where code = 'VED_TCNT2')]]))[2] as type_contrat_elsan,
(max(array[date_fin_activite::text, statut_texte]))[2] as statut_local,
(max(array[date_fin_activite::text,
CASE (SELECT valeur FROM rh.t_divers WHERE code = 'IMAGE_STATUT')
WHEN '1' THEN qualification_section_texte[(select sequence from rh.t_classes where code = (select valeur from rh.t_divers where code = 'EGAPRO_STAT'))]
WHEN '2' THEN grille_groupe_section_texte[(select sequence from rh.t_classes where code = (select valeur from rh.t_divers where code = 'EGAPRO_STAT'))]
ELSE statut_section_texte[(select sequence from rh.t_classes where code = (select valeur from rh.t_divers where code = 'EGAPRO_STAT'))] END
]))[2] as statut_elsan,
(max(array[extract(epoch from date_fin_activite), rhp_age_id]))[2] as age
from rh.v_contrats_mois_1
JOIN rh.v_profils_1 ON v_profils_1.profil_id = v_contrats_mois_1.rhp_profil_id
where 1=1
and mois_activite_id between to_char('[PERIODE]'::date, 'YYYYMM') and to_char('[TOPERIODE]'::date, 'YYYYMM')
AND rhp_etablissement_id = (CASE WHEN '[ETABLISSEMENT]' != '-1' THEN substr('[ETABLISSEMENT]', 3)::bigint ELSE rhp_etablissement_id END)
AND est_hors_periode IS DISTINCT FROM '1'
AND fictif <> '1'
group by 1,2,3,4
order by 3 desc
;
DROP TABLE IF EXISTS v_historique_paie_1
;
CREATE TEMP TABLE v_historique_paie_1 AS
select
rhp_profil_id,
v_historique_paie_1.salarie_id,
v_historique_paie_1.salarie_code,
rubrique_id,
rubrique_section_code,
nombre,
base,
montant_brut,
heures_contrat,
equivalent_temps_plein,
date_paie
from rh.v_historique_paie_1
JOIN sal_info_base ON sal_info_base.salarie_id = v_historique_paie_1.salarie_id
where 1=1
and mois_paie_id between to_char('[PERIODE]'::date, 'YYYYMM') and to_char('[TOPERIODE]'::date, 'YYYYMM')
AND rhp_etablissement_id = (CASE WHEN '[ETABLISSEMENT]' != '-1' THEN substr('[ETABLISSEMENT]', 3)::bigint ELSE rhp_etablissement_id END)
;
DROP TABLE IF EXISTS sal_abs
;
CREATE TEMP TABLE sal_abs AS
select
v_historique_paie_1.salarie_id,
v_historique_paie_1.salarie_code,
round(sum(case when false
or rubrique_section_code[(select sequence from rh.t_classes where code = 'VED_ABS')] = 'APFFOR' -- Formations OU...
or rubrique_section_code[(select sequence from rh.t_classes where code = 'VED_ABS')] ilike 'AN%' -- ... Absences non payées.
then
base.cti_division(
(CASE WHEN (SELECT valeur FROM rh.t_divers WHERE code = 'IMAGE_VALEUR') = '1' THEN nombre ELSE base END),
(7.0 * case when v_historique_paie_1.equivalent_temps_plein <= 0 then 1.0 else v_historique_paie_1.equivalent_temps_plein end))
else 0 end), 0) as nb_j_abs
from v_historique_paie_1
JOIN sal_info_base ON sal_info_base.salarie_id = v_historique_paie_1.salarie_id
where 1=1
-- and mois_paie_id between to_char('[PERIODE]'::date, 'YYYYMM') and to_char('[TOPERIODE]'::date, 'YYYYMM')
-- AND rhp_etablissement_id = (CASE WHEN '[ETABLISSEMENT]' != '-1' THEN substr('[ETABLISSEMENT]', 3)::bigint ELSE rhp_etablissement_id END)
group by 1,2
;
DROP TABLE IF EXISTS cdd_last_paie
;
CREATE TEMP TABLE cdd_last_paie AS
with profil_ids as (
select profil_id
from rh.t_classes
JOIN rh.t_classes_sections on t_classes_sections.classe_id = t_classes.oid and t_classes_sections.code = 'CDD'
JOIN rh.v_profils_1 ON v_profils_1.type_contrat_section_id[t_classes.sequence] = t_classes_sections.oid
where t_classes.code = 'VED_TCNT2')
select
salarie_id,
salarie_code,
max(date_paie) as last_date_paie
from v_historique_paie_1
JOIN profil_ids on profil_ids.profil_id = v_historique_paie_1.rhp_profil_id
where 1=1
-- and mois_paie_id between to_char('[PERIODE]'::date, 'YYYYMM') and to_char('[TOPERIODE]'::date, 'YYYYMM')
-- AND rhp_etablissement_id = (CASE WHEN '[ETABLISSEMENT]' != '-1' THEN substr('[ETABLISSEMENT]', 3)::bigint ELSE rhp_etablissement_id END)
group by 1,2
;
DROP TABLE IF EXISTS cdd_paie
;
CREATE TEMP TABLE cdd_paie AS
select
v_historique_paie_1.salarie_id,
v_historique_paie_1.salarie_code,
sum(montant_brut) as brut_total,
sum(heures_contrat) as heures_contrat,
sum(case when 1!=1
OR rubrique_section_code[(select sequence from rh.t_classes where code = 'IMG_MSB')] = 'S01SALBAS'
OR rubrique_id in (select to_id from rh.t_listes join rh.t_listes_contenu on t_listes_contenu.liste_id = t_listes.oid where t_listes.code = 'VED_P_IND')
then montant_brut else 0 end) as salaire_base
from v_historique_paie_1
JOIN cdd_last_paie on 1=1
and cdd_last_paie.salarie_id = v_historique_paie_1.salarie_id
and cdd_last_paie.last_date_paie = v_historique_paie_1.date_paie
where 1=1
-- and mois_paie_id between to_char('[PERIODE]'::date, 'YYYYMM') and to_char('[TOPERIODE]'::date, 'YYYYMM')
-- AND rhp_etablissement_id = (CASE WHEN '[ETABLISSEMENT]' != '-1' THEN substr('[ETABLISSEMENT]', 3)::bigint ELSE rhp_etablissement_id END)
group by 1,2
;
DROP TABLE IF EXISTS cdi_paie
;
CREATE TEMP TABLE cdi_paie AS
with profil_ids as (
select profil_id
from rh.t_classes
JOIN rh.t_classes_sections on t_classes_sections.classe_id = t_classes.oid and t_classes_sections.code = 'CDI'
JOIN rh.v_profils_1 ON v_profils_1.type_contrat_section_id[t_classes.sequence] = t_classes_sections.oid
where t_classes.code = 'VED_TCNT2')
select
salarie_id,
salarie_code,
sum(montant_brut) as brut_total,
sum(heures_contrat) as heures_contrat,
sum(case when 1!=1
OR rubrique_section_code[(select sequence from rh.t_classes where code = 'IMG_MSB')] = 'S01SALBAS'
OR rubrique_id in (select to_id from rh.t_listes join rh.t_listes_contenu on t_listes_contenu.liste_id = t_listes.oid where t_listes.code = 'VED_P_IND')
then montant_brut else 0 end) as salaire_base
from v_historique_paie_1
JOIN profil_ids on profil_ids.profil_id = v_historique_paie_1.rhp_profil_id
-- where mois_paie_id between to_char('[PERIODE]'::date, 'YYYYMM') and to_char('[TOPERIODE]'::date, 'YYYYMM')
group by 1,2
;
select
sal_info_base.salarie_code as matricule,
case when sal_info_base.sexe_code = 'M' then 'H' else 'F' end as sexe,
sal_info_base.nb_j_min,
sal_info_base.nb_j_contract,
sal_abs.nb_j_abs,
sal_info_base.nb_j_contract - sal_abs.nb_j_abs as nb_j_pres,
-- case when sal_info_base.nb_j_contract - sal_abs.nb_j_abs > sal_info_base.nb_j_min and sal_info_base.type_contrat_elsan in ('CDD', 'CDI') then 'oui' else 'non' end as retenu,
-- sal_info_base.type_contrat_local,
sal_info_base.type_contrat_elsan,
-- sal_info_base.statut_local,
case sal_info_base.statut_elsan
when 'Technicien' then 'Technicien et Agent de Maîtrise'
when 'Agent de Maîtrise' then 'Technicien et Agent de Maîtrise'
else sal_info_base.statut_elsan
end as statut_elsan,
sal_info_base.age,
case
when sal_info_base.age < 30 then 'moins de 30 ans'
when sal_info_base.age between 30 and 39 then '30 à 39 ans'
when sal_info_base.age between 40 and 49 then '40 à 49 ans'
when sal_info_base.age >= 50 then '50 ans et plus' end as age_tranche,
replace(round(case when sal_info_base.type_contrat_elsan = 'CDI' then cdi_paie.heures_contrat else cdd_paie.heures_contrat end, 2), '.', ',') as heures_contrat,
replace(case when sal_info_base.type_contrat_elsan = 'CDI' then cdi_paie.salaire_base else cdd_paie.salaire_base end, '.', ',') as salaire_base,
replace(round(base.cti_division((case when sal_info_base.type_contrat_elsan = 'CDI' then cdi_paie.salaire_base else cdd_paie.salaire_base end) * 1820.0, case when sal_info_base.type_contrat_elsan = 'CDI' then cdi_paie.heures_contrat else cdd_paie.heures_contrat end), 2), '.', ',') as salaire_base_annuel,
'Non'::text as augmentation,
'Non'::text as promotion
from sal_info_base
join sal_abs on sal_abs.salarie_id = sal_info_base.salarie_id
left join cdd_paie on cdd_paie.salarie_id = sal_info_base.salarie_id
left join cdi_paie on cdi_paie.salarie_id = sal_info_base.salarie_id
where 1=1
and sal_info_base.nb_j_contract - sal_abs.nb_j_abs > sal_info_base.nb_j_min
and sal_info_base.type_contrat_elsan in ('CDD', 'CDI')
-- Ne pas remonter les paie avec 0 heures contrat/salaire de base.
and case when sal_info_base.type_contrat_elsan = 'CDI' then cdi_paie.salaire_base else cdd_paie.salaire_base end != 0
order by 1
;
]]></select>
<FIELDS>
<FIELD name="MAT"/>
<FIELD name="SEX"/>
<FIELD name="NBJMIN"/>
<FIELD name="NBJCON"/>
<FIELD name="NBJABS"/>
<FIELD name="NBJPRS"/>
<FIELD name="TYCONEL"/>
<FIELD name="STATEL"/>
<FIELD name="SLRINFBASEAG"/>
<FIELD name="AGETRAN"/>
<FIELD name="HRSCNTR"/>
<FIELD name="SALBAS"/>
<FIELD name="SALBASAN"/>
<FIELD name="AUGME"/>
<FIELD name="PROMO"/>
</FIELDS>
</SQL>
</QUERY>
</QUERIES>
<CSVFILES>
<CSVFILE label="Egalite professionnelle du [PERIODE] au [TOPERIODE]" name="idx_egapro" queryNumber="0" format="CSV_PV_WITHOUT_HEADER">
<COLUMN dataField="MAT" headerText="matricule" />
<COLUMN dataField="SEX" headerText="sexe" />
<COLUMN dataField="NBJMIN" headerText="nb_j_min" />
<COLUMN dataField="NBJCON" headerText="nb_j_contract" />
<COLUMN dataField="NBJABS" headerText="nb_j_abs" />
<COLUMN dataField="NBJPRS" headerText="nb_j_pres" />
<COLUMN dataField="TYCONEL" headerText="type_contrat_elsan" />
<COLUMN dataField="STATEL" headerText="statut_elsan" />
<COLUMN dataField="SLRINFBASEAG" headerText="age" />
<COLUMN dataField="AGETRAN" headerText="age_tranche" />
<COLUMN dataField="HRSCNTR" headerText="heures_contrat" />
<COLUMN dataField="SALBAS" headerText="salaire_base" />
<COLUMN dataField="SALBASAN" headerText="salaire_base_annuel" />
<COLUMN dataField="AUGME" headerText="augmentation"/>
<COLUMN dataField="PROMO" headerText="promotion" />
</CSVFILE>
</CSVFILES>
<PRESENTATION>
</PRESENTATION>
</VUE>