PDC_REPORT_CreazioneDB/sql/storedCollaudo/C6MartPeriodico_SP_DQ_SelezioneDisallineati.sql
2025-06-06 19:02:52 +02:00

172 lines
4.0 KiB
SQL

-- Schema: C6MartPeriodico
-- Stored Procedure: SP_DQ_SelezioneDisallineati
-- =============================================
-- Author: Fabrizio Caruso
-- Create date: 17/09/2014
-- Description: Copia della SP [C6MartPeriodico].[SRV_LISTA_DISALLINEAMENTI_MONIT]
-- TODO --- Da ottimizzare per Data Quality
-- =============================================
CREATE procedure [C6MartPeriodico].[SP_DQ_SelezioneDisallineati]
AS
BEGIN
SELECT
RETE,
COD_FISCALE,
SUBSTRING(CASE WHEN ID_AREA='EXT' THEN 'Exr' ELSE ID_AREA END,0,4) AS ID_AREA,
isnull(ORDINAMENTO_PROGETTO,0) as ordinamento_progetto,
SUM(CTV) AS SUM_CTV
INTO #TEMP_PATRIMONIO_BF_AGGR
FROM
C6MARTPERIODICO.PATRIMONIO_BF
WHERE ID_AREA NOT IN ('CC','NA')
AND REND_NON_RAPPR=0
GROUP BY RETE,
COD_FISCALE,
SUBSTRING(CASE WHEN ID_AREA='EXT' THEN 'Exr' ELSE ID_AREA END,0,4),
isnull(ORDINAMENTO_PROGETTO,0)
--SELECT * INTO #TANAB FROM C6STAGINGPERIODICO.TANAB
--WHERE CODFIS IN
--(SELECT DISTINCT COD_FISCALE FROM #TEMP_PATRIMONIO_BF_AGGR)
SELECT * INTO #TANAB FROM C6STAGINGPERIODICO.TANAB
WHERE CODFIS IN
-- Modifica del 28/4/2017 per staging e mart selective
-- (select cod_fiscale from c6stagingperiodico.appo_contratti)
(select cod_fiscale from c6stagingperiodico.appo_contratti_v)
-- Fine modifica del 28/4/2017 per staging e mart selective
SELECT *
FROM
(
SELECT
P.RETE,
P.COD_FISCALE,
P.ID_AREA,
m.codarea as mon_area,
P.ORDINAMENTO_PROGETTO as bf_ordprorg,
M.CTV CTV_MONIT,
P.SUM_CTV,
(isnull(sum_ctv,0) - isnull(m.ctv,0)) as delta,
m.codprog as mon_codprog
FROM
#TANAB M,
#TEMP_PATRIMONIO_BF_AGGR P
,C6StagingPeriodico.RP_ChiaviMonitoraggio S
WHERE
M.RETE = P.RETE
AND case when len(m.CODFIS) =4 then 'FF@'+codfis else codfis end = P.COD_FISCALE
AND M.CODAREA = P.ID_AREA
AND DTFINE ='99991231'
AND M.CTV <> P.SUM_CTV
and m.ctv > 0
--AND M.CODPROG = isnull(P.ORDINAMENTO_PROGETTO,0)
AND S.chiaveprogetto=isnull(P.ORDINAMENTO_PROGETTO,0)
AND M.CODPROG = S.idmonitoraggio
and id_area ='Inv'
union all
SELECT
P.RETE,
P.COD_FISCALE,
P.ID_AREA,
m.codarea as mon_area,
P.ORDINAMENTO_PROGETTO,
M.CTV CTV_MONIT,
P.SUM_CTV,
(isnull(sum_ctv,0) - isnull(m.ctv,0)) as delta,
m.codprog
FROM
#TANAB M,
#TEMP_PATRIMONIO_BF_AGGR P
WHERE
M.RETE = P.RETE
AND case when len(m.CODFIS) =4 then 'FF@'+codfis else codfis end = P.COD_FISCALE
AND M.CODAREA = P.ID_AREA
AND DTFINE ='99991231'
AND M.CTV <> P.SUM_CTV
and m.ctv > 0
and id_area <>'Inv'
union all
--------------------------------------------
-- SOLO MONITORAGGIO
--------------------------------------------
SELECT
m.RETE,
case when len(m.CODFIS) =4 then 'FF@'+codfis else codfis end as cod_fiscale,
P.ID_AREA,
m.codarea as mon_area,
P.ORDINAMENTO_PROGETTO,
M.CTV CTV_MONIT,
P.SUM_CTV,
(isnull(sum_ctv,0) - isnull(m.ctv,0)) as delta,
m.codprog
FROM
#TANAB M
left outer join
--#TEMP_PATRIMONIO_BF_AGGR P
(select T.*,S.idmonitoraggio from
#TEMP_PATRIMONIO_BF_AGGR T
,C6StagingPeriodico.RP_ChiaviMonitoraggio S
where S.chiaveprogetto=isnull(T.ORDINAMENTO_PROGETTO,0)
)P
on
M.RETE = P.RETE
AND case when len(m.CODFIS) =4 then 'FF@'+codfis else codfis end = P.COD_FISCALE
AND M.CODAREA = P.ID_AREA
AND M.CODPROG = P.idmonitoraggio
AND DTFINE ='99991231'
where
m.ctv > 0
and p.cod_fiscale is null
--AND M.CODPROG = isnull(P.ORDINAMENTO_PROGETTO,0)
--and id_area ='Inv'
and m.codarea ='Inv'
union all
SELECT
m.RETE,
case when len(m.CODFIS) =4 then 'FF@'+codfis else codfis end as cod_fiscale,
p.ID_AREA,
m.codarea as mon_area,
P.ORDINAMENTO_PROGETTO,
M.CTV CTV_MONIT,
P.SUM_CTV,
(isnull(sum_ctv,0) - isnull(m.ctv,0)) as delta,
m.codprog
FROM
#TANAB M
left outer join
#TEMP_PATRIMONIO_BF_AGGR P
on
M.RETE = P.RETE
--AND M.CODFIS = P.COD_FISCALE
AND case when len(m.CODFIS) =4 then 'FF@'+m.codfis else m.codfis end = P.COD_FISCALE
AND M.CODAREA = P.ID_AREA
where
DTFINE ='99991231'
and m.ctv > 0
and p.cod_fiscale is null
and codarea <>'Inv'
) k
order by 2,1