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.
 
 
 

209 lines
7.3 KiB

<?xml version="1.0" encoding="ISO-8859-1"?>
<VUE name="RH000095" label="RH. Contrôles Sigems" title="RH. Contrôles Sigems"
database="iCTI"
swf="*CTI_view1"
softCode="iCTI_rh"
rhProvider="sigems">
<QUERIES>
<QUERY label="">
<SQL optimizer="">
<select><![CDATA[
DROP TABLE IF EXISTS w_erreur
;
CREATE TEMP TABLE w_erreur AS
SELECT
contrats_pb.mat AS salarie,
'Pas d''affectation'::text AS erreur,
'' AS commentaire
FROM prod_sigems.contrats_pb
LEFT JOIN prod_sigems.grh_histo_affec ON 1=1
AND grh_histo_affec.mat = contrats_pb.mat
WHERE grh_histo_affec.mat is null
UNION ALL
SELECT
mat AS salarie,
'Affectation : date de début > date de fin'::text AS erreur,
'Affectation du '||to_char(dtdu, 'DD/MM/YYYY')||' au '||to_char(dtau, 'DD/MM/YYYY') AS commentaire
FROM prod_sigems.grh_histo_affec
WHERE dtdu > dtau
UNION ALL
SELECT
mat,
'Affectation : date de début non renseignée' AS erreur,
(sum(CASE WHEN dtdu IS NULL OR char_length(dtdu) = 0 THEN 1 ELSE 0 END) - 1)::text || ' date(s) non renseignée(s)'
FROM prod_sigems.grh_histo_affec
GROUP BY 1
HAVING sum(CASE WHEN dtdu IS NULL OR char_length(dtdu) = 0 THEN 1 ELSE 0 END) > 1
UNION ALL
SELECT
mat,
'Affectation : date de fin non renseignée' AS erreur,
(sum(CASE WHEN dtau IS NULL OR char_length(dtau) = 0 THEN 1 ELSE 0 END) - 1)::text || ' date(s) non renseignée(s)'
FROM prod_sigems.grh_histo_affec
GROUP BY 1
HAVING sum(CASE WHEN dtau IS NULL OR char_length(dtau) = 0 THEN 1 ELSE 0 END) > 1
UNION ALL
SELECT
g1.mat,
'Affectation : chevauchement' AS erreur,
'Du '||to_char(g1.dtdu, 'dd/mm/YYYY')||' au '||to_char(g1.dtau, 'dd/mm/YYYY')||' (id '||g1.id_cont||') et du '||
to_char(g2.dtdu, 'dd/mm/YYYY')||' au '||to_char(g2.dtau, 'dd/mm/YYYY')||' (id '||g2.id_cont||')'::text
FROM prod_sigems.grh_histo_affec AS g1
JOIN prod_sigems.grh_histo_affec AS g2 ON g2.mat = g1.mat
WHERE 1=1
AND base.cti_overlaps(g1.dtdu::date, g1.dtau::date, g2.dtdu::date, g2.dtau::date)
AND g1.id_enreg != g2.id_enreg
GROUP BY 1,2,3
UNION ALL
SELECT
mat AS salarie,
'Contrat : date de début > date de fin' AS erreur,
'Contrat du '||to_char(dtdebu, 'DD/MM/YYYY')||' au '||to_char(dtsort, 'DD/MM/YYYY') AS commentaire
FROM prod_sigems.contrats_pb
WHERE dtdebu > dtsort
UNION ALL
SELECT
mat,
'Contrat : date de début non renseignée' AS erreur,
(sum(CASE WHEN dtdebu IS NULL OR char_length(dtdebu) = 0 THEN 1 ELSE 0 END) - 1)::text || ' date(s) non renseignée(s)'
FROM prod_sigems.contrats_pb
GROUP BY 1
HAVING sum(CASE WHEN dtdebu IS NULL OR char_length(dtdebu) = 0 THEN 1 ELSE 0 END) > 1
UNION ALL
SELECT
mat,
'Contrat : date de fin non renseignée' AS erreur,
(sum(CASE WHEN dtsort IS NULL OR char_length(dtsort) = 0 THEN 1 ELSE 0 END) - 1)::text || ' date(s) non renseignée(s)'
FROM prod_sigems.contrats_pb
GROUP BY 1
HAVING sum(CASE WHEN dtsort IS NULL OR char_length(dtsort) = 0 THEN 1 ELSE 0 END) > 1
UNION ALL
SELECT
g1.mat,
'Contrat : chevauchement' AS erreur,
(count(*) / 2)::text || ' chevauchements(s)'
FROM prod_sigems.contrats_pb AS g1
JOIN prod_sigems.contrats_pb AS g2 ON g2.mat = g1.mat
WHERE 1=1
AND base.cti_overlaps(g1.dtdebu::date, g1.dtsort::date, g2.dtdebu::date, g2.dtsort::date)
AND g1.id_cont != g2.id_cont
GROUP BY 1
UNION ALL
SELECT
mat,
'Contrat hors période d''affectation' AS erreur,
'Contrat du '||to_char(dtdebu, 'DD/MM/YYYY')||' au '||to_char(dtsort, 'DD/MM/YYYY')||' (id '||contrats_pb.id_cont||')' AS commentaire
FROM prod_sigems.contrats_pb
LEFT JOIN (
SELECT contrats_pb.id_cont
FROM prod_sigems.contrats_pb
JOIN prod_sigems.grh_histo_affec ON 1=1
AND grh_histo_affec.mat = contrats_pb.mat
AND base.cti_overlaps(
dtdebu::date,
(CASE WHEN dtsort IS NULL OR char_length(dtsort) = 0 THEN '2099-12-31'::date ELSE dtsort END)::date,
dtdu::date,
(CASE WHEN dtau IS NULL OR char_length(dtau) = 0 THEN '2099-12-31'::date ELSE dtau END)::date
)
) AS subq ON subq.id_cont = contrats_pb.id_cont
WHERE subq.id_cont IS NULL
/*
UNION ALL
SELECT
contrats_pb.mat,
'Contrat partiellement couvert par période d''affectation' AS erreur,
'Contrat du '||to_char(dtdebu, 'DD/MM/YYYY')||' au '||coalesce(to_char(dtsort, 'DD/MM/YYYY'), 'N/R')
||' et affectation du '||to_char(min(dtdu::date), 'DD/MM/YYYY')
||' au '||max((CASE WHEN dtau IS NULL OR char_length(dtau) = 0 THEN 'N/R' ELSE to_char(dtau, 'DD/MM/YYYY') END)) AS commentaire
FROM prod_sigems.contrats_pb
JOIN prod_sigems.grh_histo_affec ON 1=1
AND grh_histo_affec.mat = contrats_pb.mat
AND grh_histo_affec.id_cont = contrats_pb.id_cont
AND base.cti_overlaps(
dtdebu::date,
(CASE WHEN dtsort IS NULL OR char_length(dtsort) = 0 THEN '2099-12-31'::date ELSE dtsort END)::date,
dtdu::date,
(CASE WHEN dtau IS NULL OR char_length(dtau) = 0 THEN '2099-12-31'::date ELSE dtau END)::date
)
group by 1,dtdebu,dtsort
having ((CASE WHEN dtsort IS NULL OR char_length(dtsort) = 0 THEN '2099-12-31'::date ELSE dtsort END)::date - dtdebu::date)
> (max((CASE WHEN dtau IS NULL OR char_length(dtau) = 0 THEN '2099-12-31'::date ELSE dtau END)::date) - min(dtdu)::date)
*/
;
(
SELECT
1,
mat,
mat AS salarie,
count(*)::text||' erreur(s)',
''
FROM w_erreur
JOIN prod_sigems.pers ON pers.mat = w_erreur.salarie
WHERE 1=1
AND mat != ''
AND c_anu != 'O'
GROUP BY 1,2,3
)
UNION ALL
(
SELECT
2,
salarie,
'',
w_erreur.erreur,
w_erreur.commentaire
FROM w_erreur
JOIN prod_sigems.pers ON pers.mat = w_erreur.salarie
WHERE 1=1
AND mat != ''
AND c_anu != 'O'
)
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="Affectations - Date début > Date fin" 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" width="350" />
<COLUMN dataField="COM" type="Char" headerText="Commentaire" minWidth="350" />
</DATAGRID>
</ONGLET>
</PRESENTATION>
</VUE>