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.
 
 
 

114 lines
3.6 KiB

<?xml version="1.0" encoding="ISO-8859-1"?>
<VUE name="RH000100" label="RH. Contrôles Cegid" title="RH. Contrôles Cegid"
database="iCTI"
swf="*CTI_view1"
softCode="iCTI_rh"
rhProvider="cegid">
<QUERIES>
<QUERY label="">
<SQL optimizer="">
<select><![CDATA[
-- Identification des salariés ayant eut un changement de type de contrat d'après l'historique de paie.
drop table if exists w_sal_chgmt
;
create temp table w_sal_chgmt as
select
ppu_salarie as matricule
from prod_cegid.paieencours
group by 1
having count(distinct ppu_travailn1) > 1
;
-- Recensement des informations relatives au changement de contrats
drop table if exists w_chgmt
;
create temp table w_chgmt as
select
ppu_salarie as matricule,
ppu_travailn1 AS type_contrat,
min(ppu_datedebut) AS date_debut
from prod_cegid.paieencours
where ppu_salarie in (select matricule from w_sal_chgmt)
group by 1,2
having min(ppu_datedebut) != '2008-01-01'
order by 1,2,3
;
-- Recensement des erreurs avant présentation
DROP TABLE IF EXISTS w_erreur
;
CREATE TEMP TABLE w_erreur AS
SELECT
t1.pci_salarie AS mat,
'Chevauchement de contrats'::text AS erreur,
'Chevauchement de '||t1.pci_ordre||' et '||t2.pci_ordre AS commentaire
FROM prod_cegid.contrattravail as t1
JOIN prod_cegid.contrattravail as t2 ON 1=1
AND t2.pci_salarie = t1.pci_salarie
AND t1.pci_debutcontrat::date != t2.pci_debutcontrat::date
AND t1.pci_fincontrat::date != t2.pci_fincontrat::date
AND base.cti_overlaps(t1.pci_debutcontrat::date, CASE WHEN t1.pci_fincontrat::date = '1900-01-01'::date THEN '2099-12-31' ELSE t1.pci_fincontrat::date END, t2.pci_debutcontrat::date, CASE WHEN t2.pci_fincontrat::date = '1900-01-01'::date THEN '2099-12-31' ELSE t2.pci_fincontrat::date END)
UNION ALL
select
matricule as mat,
'Changement de type de contrat discordant entre historiques de paie et contrat'::text AS erreur,
'Date de changement dans la paie : '||to_char(date_debut, 'dd/mm/YYYY')||' vers le type '||type_contrat AS commentaire
from w_chgmt
left join prod_cegid.contrattravail ON 1=1
AND matricule = pci_salarie
AND date_debut = pci_debutcontrat
where pci_salarie is null
;
-- Présentation des erreurs
(
SELECT
1,
mat,
mat AS salarie,
count(*)::text||' erreur(s)',
''
FROM w_erreur
GROUP BY 1,2,3
)
UNION ALL
(
SELECT
2,
mat,
'',
w_erreur.erreur,
w_erreur.commentaire
FROM w_erreur
)
ORDER BY 2,1
;
]]></select>
<FIELDS>
<FIELD name="LVL"/>
<FIELD name="MAT"/>
<FIELD name="SAL"/>
<FIELD name="ERR"/>
<FIELD name="COM"/>
</FIELDS>
</SQL>
</QUERY>
</QUERIES>
<PRESENTATION>
<ONGLET label="Erreurs" queryNumber="0" newPage="true">
<DATAGRID sortable="false">
<ROWSTYLE name="backgroundColor" value="0xFFFF99" condition="ROW.LVL == '1'" />
<ROWSTYLE name="fontWeight" value="bold" condition="ROW.LVL == '1'" />
<COLUMN dataField="LVL" type="Number" headerText="Niveau" width="80" visible="false" />
<COLUMN dataField="SAL" type="Char" headerText="[DICT.RH.SALARIE#1]" width="80" />
<COLUMN dataField="ERR" type="Char" headerText="Erreur" minWidth="300" />
<COLUMN dataField="COM" type="Char" headerText="Commentaire" width="350" />
</DATAGRID>
</ONGLET>
</PRESENTATION>
</VUE>