PDC_REPORT_CreazioneDB/sql/storedCollaudo/C6MartPeriodicoImmobiliare_PL_MP_S140AnalisiRisparmioCharts.sql
2025-06-09 17:09:11 +02:00

338 lines
10 KiB
SQL

-- [C6MartPeriodicoImmobiliare].[PL_MP_S140AnalisiRisparmioCharts] 'S','RTRRLF23S12Z105V'
CREATE PROCEDURE [C6MartPeriodicoImmobiliare].[PL_MP_S140AnalisiRisparmioCharts]
@Rete char(1), @CodiceFiscale varchar(16)
WITH EXEC AS CALLER
AS
BEGIN
SET NOCOUNT ON;
--QUERY PER INTERMEDIARIO
SELECT
RETE,
COD_FISCALE,
INTERMEDIARIO,
CASE WHEN INTERMEDIARIO IN ( 'Fideuram', 'Sanpaolo Invest') THEN 1
ELSE 2 END AS ORDINE,
SUM(CTV) AS CTV_TOT,
SUM(CASE WHEN RISKCLASS = 'NON COPERTO' THEN CTV ELSE 0 END) AS CTV_notCovered,
SUM(CASE WHEN RISKCLASS = 'Classe A'
or RISKCLASS = 'Classe B'
or RISKCLASS = 'Classe C'
or RISKCLASS = 'Classe D'
THEN CTV ELSE 0 END) AS CTV_CreditRisk,
SUM(CASE WHEN RISKCLASS = 'NA' THEN CTV ELSE 0 END) AS CTV_na,
--CASE WHEN SUM(CTV)=0 THEN 0 ELSE (SUM(CASE WHEN RISKCLASS = 'NON COPERTO' THEN CTV ELSE 0 END)/SUM(CTV))*100 END AS PERC_notCovered,
CASE WHEN SUM(CTV)=0 THEN 0 ELSE (SUM(CASE WHEN RISKCLASS = 'Classe A'
or RISKCLASS = 'Classe B'
or RISKCLASS = 'Classe C'
or RISKCLASS = 'Classe D' THEN CTV ELSE 0 END)
/SUM(CASE WHEN RISKCLASS <> 'NON COPERTO' THEN CTV ELSE 1 END)
)*100 END AS PERC_CreditRisk,
CASE WHEN SUM(CTV)=0 THEN 0 ELSE (SUM(CASE WHEN RISKCLASS = 'NA' THEN CTV ELSE 0 END) /sum(CASE WHEN RISKCLASS <> 'NON COPERTO' THEN CTV ELSE 1 END))*100 END as PERC_NA
FROM
(
-- Start 1.1
SELECT
PATRBF.RETE,
PATRBF.COD_FISCALE,
CASE
WHEN RISCHIO_PROD.COPERTURA < 100
THEN 'NON COPERTO'
WHEN DESCRIZIONE IS NULL
THEN 'NA'
ELSE DESCRIZIONE
END AS RISKCLASS,
CASE WHEN PATRBF.RETE = 'F' THEN 'Fideuram' ELSE 'Sanpaolo Invest' END AS INTERMEDIARIO,
--SUM(CASE WHEN PATRBF.ID_AREA = 'Cc' AND PATRBF.CTV < 0 THEN 0 ELSE PATRBF.CTV END) AS CTV
--INIZIO INTERVENTI OMNIA
--SUM(CASE WHEN ctvcc.cc_ctv <0 and patrbf.id_area='cc' THEN 0 ELSE PATRBF.CTV END) AS ctv
SUM(CASE WHEN ctvcc.cc_ctv <0 and patrbf.id_area='cc' THEN 0
WHEN ctvself.self_ctv <0 and patrbf.id_area='self' THEN 0
ELSE PATRBF.CTV END) AS ctv
--FINE INTERVENTI OMNIA
FROM
[C6MartPeriodicoImmobiliare].PATRIMONIO_BF PATRBF
---Per calcolare la somma algebrica dei cc
LEFT OUTER JOIN
(select cod_fiscale, rete, sum(ctv) as cc_ctv
from
[C6MartPeriodicoImmobiliare].pATRIMONIO_BF
where id_Area='Cc'
group by cod_fiscale, rete
) ctvcc
on
patrbf.cod_fiscale=ctvcc.cod_fiscale
and
patrbf.rete=ctvcc.rete
--fine calcolo somma cc
--INIZIO INTERVENTI OMNIA
---Per calcolare la somma algebrica dei self negativi
LEFT OUTER JOIN
(select cod_fiscale, rete, sum(ctv) as self_ctv
from
[C6MartPeriodicoImmobiliare].pATRIMONIO_BF
where id_Area='Self'
group by cod_fiscale, rete
) ctvself
on
patrbf.cod_fiscale=ctvself.cod_fiscale
and
patrbf.rete=ctvself.rete
--fine calcolo somma self negativi
--FINE INTERVENTI OMNIA
LEFT OUTER JOIN
[C6MartPeriodicoImmobiliare].RISCHIO_AGGREGATO RISCHIO_PROD
ON
PATRBF.RETE= RISCHIO_PROD.RETE
AND PATRBF.COD_FISCALE= RISCHIO_PROD.COD_FISCALE
AND RISCHIO_PROD.COD_AGGREG =
CASE
WHEN (PATRBF.NOME_PROGETTO IS NOT NULL)
THEN 'RISFIN|PIRAMIDE|' + LEFT(PATRBF.ID_AREA,3) + '|' + PATRBF.NOME_PROGETTO + '|' + isnull(cast(PATRBF.ordinamento_progetto as varchar),'') + '|'
--V
WHEN (PATRBF.NOME_PROGETTO IS NULL) AND PATRBF.ID_AREA IN ('EXT','INV','PRE','RIS','LIQ')
THEN 'RISFIN|PIRAMIDE|' + LEFT(PATRBF.ID_AREA,3) + '|'
WHEN (PATRBF.NOME_PROGETTO IS NULL) AND PATRBF.ID_AREA IN ('CC')
THEN 'COMPLESSIVO|BF|CC|' + LEFT(PATRBF.ID_AREA,3) + '|'
WHEN (PATRBF.NOME_PROGETTO IS NULL) AND PATRBF.ID_AREA IN ('NA')
THEN 'RISFIN|' + LEFT(PATRBF.ID_AREA,3) + '|'
--
END + PATRBF.POSITION_ID
--INNER JOIN C6MartPeriodicoImmobiliare.CODIFICA_CREDITRISK CR
LEFT outer JOIN C6MartPeriodicoImmobiliare.CODIFICA_CREDITRISK CR
ON RISCHIO_PROD.CREDITRISK = cr.profilo
--V
WHERE PATRBF.COD_FISCALE = @CodiceFiscale AND
PATRBF.RETE = @Rete
--
GROUP BY
PATRBF.RETE,
PATRBF.COD_FISCALE,
CASE
WHEN RISCHIO_PROD.COPERTURA < 100
THEN 'NON COPERTO'
WHEN DESCRIZIONE IS NULL
THEN 'NA'
ELSE DESCRIZIONE
END,
CASE WHEN PATRBF.RETE = 'F' THEN 'FIDEURAM' ELSE 'SANPAOLO' END
--- End 1.1
UNION ALL
-- Start 1.2
SELECT
PATRTERZI.RETE,
PATRTERZI.COD_FISCALE,
CASE
WHEN RISCHIOPROD.COPERTURA < 100
THEN 'NON COPERTO'
WHEN DESCRIZIONE IS NULL
THEN 'NA'
ELSE DESCRIZIONE
END AS RISKCLASS,
PATRTERZI.INTERMEDIARIO,
SUM(ROUND(CTV,2)) AS CTV
FROM
[C6MartPeriodicoImmobiliare].PATRIMONIO_TERZI PATRTERZI
LEFT OUTER JOIN
(select cod_fiscale, rete, sum(ctv) as cc_ctv
from
[C6MartPeriodicoImmobiliare].pATRIMONIO_terzi
where tipo_prodotto='Conti correnti'
group by cod_fiscale, rete
) ctvcc
on
patrterzi.cod_fiscale=ctvcc.cod_fiscale
and
patrterzi.rete=ctvcc.rete
LEFT OUTER JOIN
[C6MartPeriodicoImmobiliare].RISCHIO_AGGREGATO RISCHIOPROD
ON
PATRTERZI.RETE = RISCHIOPROD.RETE
AND PATRTERZI.COD_FISCALE = RISCHIOPROD.COD_FISCALE
AND RISCHIOPROD.COD_AGGREG ='TIPOPRODTERZI|TERZI|' +ISNULL(PATRTERZI.DESCR_GRUPPO_PRODOTTO, PATRTERZI.TIPO_PRODOTTO) + '|'+ PATRTERZI.COD_PRODOTTO_TERZI
left outer JOIN [C6MartPeriodicoImmobiliare].CODIFICA_CREDITRISK CR
ON RISCHIOPROD.CREDITRISK = cr.profilo
--V
WHERE PATRTERZI.COD_FISCALE = @CodiceFiscale AND
PATRTERZI.RETE = @Rete
--
GROUP BY
PATRTERZI.RETE,
PATRTERZI.COD_FISCALE,
PATRTERZI.INTERMEDIARIO,
CASE
WHEN RISCHIOPROD.COPERTURA < 100
THEN 'NON COPERTO'
WHEN DESCRIZIONE IS NULL
THEN 'NA'
ELSE DESCRIZIONE
END
-- End 1.2
)H
GROUP BY
RETE,
COD_FISCALE,
INTERMEDIARIO
--------
UNION ALL
-----------
--QUERY TOTALE
SELECT
RETE,
COD_FISCALE,
'Complessivo' AS INTERMEDIARIO,
3 AS ORDINE,
SUM(CTV) AS CTV_TOT,
SUM(CASE WHEN RISKCLASS = 'NON COPERTO' THEN CTV ELSE 0 END) AS CTV_notCovered,
SUM(CASE WHEN RISKCLASS = 'Classe A'
or RISKCLASS = 'Classe B'
or RISKCLASS = 'Classe C'
or RISKCLASS = 'Classe D'
THEN CTV ELSE 0 END) AS CTV_CreditRisk,
SUM(CASE WHEN RISKCLASS ='NA' THEN CTV ELSE 0 END) AS CTV_na,
--CASE WHEN SUM(CTV)=0 THEN 0 ELSE (SUM(CASE WHEN RISKCLASS = 'NON COPERTO' THEN CTV ELSE 0 END)/SUM(CTV))*100 END AS PERC_notCovered,
CASE WHEN SUM(CTV)=0 THEN 0 ELSE (SUM(CASE WHEN RISKCLASS = 'Classe A'
or RISKCLASS = 'Classe B'
or RISKCLASS = 'Classe C'
or RISKCLASS = 'Classe D' THEN CTV ELSE 0 END)
/SUM(CASE WHEN RISKCLASS <> 'NON COPERTO' THEN CTV ELSE 1 END)
)*100 END AS PERC_CreditRisk,
CASE WHEN SUM(CTV)=0 THEN 0 ELSE (SUM(CASE WHEN RISKCLASS = 'NA' THEN CTV ELSE 0 END) /sum(CASE WHEN RISKCLASS <> 'NON COPERTO' THEN CTV ELSE 1 END))*100 END as PERC_NA
FROM
(
--- Start 2.1
SELECT
PATRBF.RETE,
PATRBF.COD_FISCALE,
CASE
WHEN RISCHIO_PROD.COPERTURA < 100
THEN 'NON COPERTO'
WHEN DESCRIZIONE IS NULL
THEN 'NA'
ELSE DESCRIZIONE
END AS RISKCLASS,
--SUM(CASE WHEN PATRBF.ID_AREA = 'Cc' AND PATRBF.CTV < 0 THEN 0 ELSE PATRBF.CTV END) AS CTV
--INIZIO INTERVENTI OMNIA
--SUM(CASE WHEN ctvcc.cc_ctv <0 and patrbf.id_area='cc' THEN 0 ELSE PATRBF.CTV END) AS CTV
SUM(CASE WHEN ctvcc.cc_ctv <0 and patrbf.id_area='cc' THEN 0
WHEN ctvself.self_ctv <0 and patrbf.id_area='self' THEN 0
ELSE PATRBF.CTV END) AS CTV
--FINE INTERVENTI OMNIA
FROM
[C6MartPeriodicoImmobiliare].PATRIMONIO_BF PATRBF
--per fare la somma algebrica dei cc
LEFT OUTER JOIN
(select cod_fiscale, rete, sum(ctv) as cc_ctv
from
[C6MartPeriodicoImmobiliare].pATRIMONIO_BF
where id_Area='Cc'
group by cod_fiscale, rete
) ctvcc
on
patrbf.cod_fiscale=ctvcc.cod_fiscale
and
patrbf.rete=ctvcc.rete
--fine somma cc
--INIZIO INTERVENTI OMNIA
--per fare la somma algebrica dei self negativi
LEFT OUTER JOIN
(select cod_fiscale, rete, sum(ctv) as self_ctv
from
[C6MartPeriodicoImmobiliare].pATRIMONIO_BF
where id_Area='Self'
group by cod_fiscale, rete
) ctvself
on
patrbf.cod_fiscale=ctvself.cod_fiscale
and
patrbf.rete=ctvself.rete
--fine somma Self negativi
--FINE INTERVENTI OMNIA
LEFT OUTER JOIN
[C6MartPeriodicoImmobiliare].RISCHIO_AGGREGATO RISCHIO_PROD
ON
PATRBF.RETE= RISCHIO_PROD.RETE
AND PATRBF.COD_FISCALE= RISCHIO_PROD.COD_FISCALE
AND RISCHIO_PROD.COD_AGGREG =
CASE
WHEN (PATRBF.NOME_PROGETTO IS NOT NULL)
THEN 'RISFIN|PIRAMIDE|' + LEFT(PATRBF.ID_AREA,3) + '|' + PATRBF.NOME_PROGETTO+ '|' + isnull(cast(PATRBF.ordinamento_progetto as varchar),'')+'|'
--V
WHEN (PATRBF.NOME_PROGETTO IS NULL) AND PATRBF.ID_AREA IN ('EXT','INV','PRE','RIS','LIQ')
THEN 'RISFIN|PIRAMIDE|' + LEFT(PATRBF.ID_AREA,3) + '|'
WHEN (PATRBF.NOME_PROGETTO IS NULL) AND PATRBF.ID_AREA IN ('CC')
THEN 'COMPLESSIVO|BF|CC|' + LEFT(PATRBF.ID_AREA,3) + '|'
WHEN (PATRBF.NOME_PROGETTO IS NULL) AND PATRBF.ID_AREA IN ('NA')
THEN 'RISFIN|' + LEFT(PATRBF.ID_AREA,3) + '|'
--
END + PATRBF.POSITION_ID
left outer JOIN [C6MartPeriodicoImmobiliare].CODIFICA_CREDITRISK CR
ON RISCHIO_PROD.CREDITRISK = cr.profilo
--V
WHERE PATRBF.COD_FISCALE = @CodiceFiscale AND
PATRBF.RETE = @Rete
--
GROUP BY
PATRBF.RETE,
PATRBF.COD_FISCALE,
CASE
WHEN RISCHIO_PROD.COPERTURA < 100
THEN 'NON COPERTO'
WHEN DESCRIZIONE IS NULL
THEN 'NA'
ELSE DESCRIZIONE
END
-- End 2.1
UNION ALL
-- Start 2.2
SELECT
PATRTERZI.RETE,
PATRTERZI.COD_FISCALE,
CASE
WHEN RISCHIOPROD.COPERTURA < 100
THEN 'NON COPERTO'
WHEN DESCRIZIONE IS NULL
THEN 'NA'
ELSE DESCRIZIONE
END AS RISKCLASS,
SUM(ROUND(CTV,2)) AS CTV
FROM
[C6MartPeriodicoImmobiliare].PATRIMONIO_TERZI PATRTERZI
left outer join
(select cod_fiscale, rete, sum(ctv) as cc_ctv
from
[C6MartPeriodicoImmobiliare].pATRIMONIO_terzi
where tipo_prodotto='Conti correnti'
group by cod_fiscale, rete
) ctvcc
on
patrterzi.cod_fiscale=ctvcc.cod_fiscale
and
patrterzi.rete=ctvcc.rete
LEFT OUTER JOIN
[C6MartPeriodicoImmobiliare].RISCHIO_AGGREGATO RISCHIOPROD
ON
PATRTERZI.RETE = RISCHIOPROD.RETE
AND PATRTERZI.COD_FISCALE = RISCHIOPROD.COD_FISCALE
AND RISCHIOPROD.COD_AGGREG ='TIPOPRODTERZI|TERZI|' + ISNULL(PATRTERZI.DESCR_GRUPPO_PRODOTTO, PATRTERZI.TIPO_PRODOTTO) + '|'+ PATRTERZI.COD_PRODOTTO_TERZI
left outer JOIN [C6MartPeriodicoImmobiliare].CODIFICA_CREDITRISK CR
ON RISCHIOPROD.CREDITRISK = cr.profilo
--V
WHERE PATRTERZI.COD_FISCALE = @CodiceFiscale
AND PATRTERZI.RETE = @Rete
--
GROUP BY
PATRTERZI.RETE,
PATRTERZI.COD_FISCALE,
CASE
WHEN RISCHIOPROD.COPERTURA < 100
THEN 'NON COPERTO'
WHEN DESCRIZIONE IS NULL
THEN 'NA'
ELSE DESCRIZIONE
END
--- End 2.2
)H
GROUP BY
RETE,
COD_FISCALE
END