140 lines
3.9 KiB
Transact-SQL
140 lines
3.9 KiB
Transact-SQL
-- Schema: C6Mart
|
|
-- Stored Procedure: PL_S96RischiomercatoRischiocredito_old
|
|
|
|
|
|
|
|
|
|
|
|
|
|
-- =============================================
|
|
-- Author: <Alessandro Tringali>
|
|
-- Create date: <Create Date,,>
|
|
-- Description: <Description,,>
|
|
-- =============================================
|
|
--[C6Mart].[PL_S96RischiomercatoRischiocredito] 'F','BRNDRA65B04B300I'
|
|
CREATE procedure [C6Mart].[PL_S96RischiomercatoRischiocredito_old]
|
|
-- Add the parameters for the stored procedure here
|
|
@Rete char(1),
|
|
@CodiceFiscale varchar(16)
|
|
AS
|
|
BEGIN
|
|
-- SET NOCOUNT ON added to prevent extra result sets from
|
|
-- interfering with SELECT statements.
|
|
SET NOCOUNT ON;
|
|
|
|
--V VARIABILI DI APPOGGIO PER LA VERIFICA SE IL CLIENTE HA SOLO CC
|
|
DECLARE @ESISTECC INT
|
|
DECLARE @NUMPOSIZIONI INT
|
|
|
|
SELECT @ESISTECC = COUNT(DISTINCT COD_FISCALE)
|
|
FROM C6MART.PATRIMONIO_BF
|
|
WHERE ID_AREA = 'CC'
|
|
AND COD_FISCALE = @CodiceFiscale
|
|
GROUP BY ID_AREA
|
|
|
|
SELECT @NUMPOSIZIONI = COUNT(*)
|
|
FROM C6MART.PATRIMONIO_BF
|
|
WHERE ID_AREA <> 'CC'
|
|
AND COD_FISCALE = @CodiceFiscale
|
|
|
|
SELECT
|
|
PATRBF.RETE,
|
|
PATRBF.COD_FISCALE,
|
|
PATRBF.INSTITUTENAME,
|
|
CTV,
|
|
M.PROFILO_ASS AS CODICEPROFILO,
|
|
CR.MAX_VAR AS VARMAX,
|
|
|
|
CASE WHEN (@ESISTECC - @NUMPOSIZIONI) > 0 and institutename in ('Patrimonio Banca Fideuram','Patrimonio Sanpaolo Invest') THEN 0
|
|
ELSE RISK_AGG.VAR_PERC_PTF
|
|
END AS VAR ,
|
|
|
|
CASE
|
|
WHEN (@ESISTECC - @NUMPOSIZIONI) > 0 THEN NULL
|
|
WHEN ISNULL(RISK_AGG.COPERTURA,0.00) = 0.00 THEN 'n.c.'
|
|
ELSE NULL
|
|
END AS VARSTRING,
|
|
RISK_AGG.CREDITRISK RISKCLASS,
|
|
CASE
|
|
WHEN (@ESISTECC - @NUMPOSIZIONI) > 0 THEN 'n.a.'
|
|
WHEN ISNULL(RISK_AGG.COPERTURA,0.00) = 0.00 THEN 'n.c.'
|
|
WHEN RISK_AGG.creditrisk is null THEN 'n.a.'
|
|
ELSE NULL
|
|
END AS RISKCLASSSTRING,
|
|
CASE
|
|
WHEN (@ESISTECC - @NUMPOSIZIONI) > 0 THEN 100
|
|
ELSE ISNULL(RISK_AGG.COPERTURA,0.00)
|
|
END AS COVERAGE,
|
|
CASE
|
|
WHEN (@ESISTECC - @NUMPOSIZIONI) > 0 THEN NULL
|
|
WHEN ISNULL(RISK_AGG.COPERTURA,0.00) = 0.00 THEN 'n.c.'
|
|
ELSE NULL
|
|
END AS COVERAGESTRING,
|
|
M.RISKCLASS AS RISKCLASSMAX,
|
|
(SUM(CTV) OVER (PARTITION BY PATRBF.COD_FISCALE,PATRBF.RETE, PATRBF.INSTITUTENAME) / SUM(CTV) OVER (PARTITION BY PATRBF.RETE, PATRBF.COD_FISCALE) )*100 AS PERCENTAGE,
|
|
ORDINE
|
|
FROM
|
|
(
|
|
select
|
|
PATRBF.RETE,
|
|
PATRBF.COD_FISCALE,
|
|
CASE WHEN PATRBF.RETE='F' THEN 'Patrimonio Banca Fideuram' ELSE 'Patrimonio Sanpaolo Invest' END AS INSTITUTENAME,
|
|
SUM(PATRBF.CTV) AS CTV,
|
|
1 as ORDINE
|
|
from
|
|
c6mart.patrimonio_bf PATRBF
|
|
where
|
|
1=1
|
|
and cod_fiscale = @codiceFiscale
|
|
and rete= @rete
|
|
GROUP BY
|
|
PATRBF.RETE,
|
|
PATRBF.COD_FISCALE,
|
|
CASE WHEN PATRBF.RETE='F' THEN 'Patrimonio Banca Fideuram' ELSE 'Patrimonio Sanpaolo Invest' END
|
|
|
|
UNION
|
|
|
|
SELECT
|
|
TERZI.RETE,
|
|
TERZI.COD_FISCALE,
|
|
'Patrimonio altri Istituti' AS INSTITUTENAME,
|
|
--SUM(TERZI.CTV) AS CTV,
|
|
SUM(ROUND(TERZI.CTV,2)) AS CTV,
|
|
2 as ORDINE
|
|
FROM
|
|
C6MART.PATRIMONIO_TERZI TERZI
|
|
where
|
|
1=1
|
|
and cod_fiscale =@codiceFiscale
|
|
and rete=@rete
|
|
GROUP BY
|
|
TERZI.RETE,
|
|
TERZI.COD_FISCALE
|
|
|
|
) PATRBF
|
|
LEFT OUTER JOIN
|
|
C6Mart.MIFID AS M
|
|
ON
|
|
PATRBF.COD_FISCALE=M.COD_FISCALE
|
|
AND PATRBF.RETE=M.RETE
|
|
LEFT OUTER JOIN C6Mart.CODIFICA_RISCHIO AS CR
|
|
ON M.PROFILO_ASS = CR.PROFILO
|
|
LEFT OUTER JOIN
|
|
c6mart.CODIFICA_CREDITRISK CK
|
|
ON
|
|
-- tringali
|
|
M.riskclass=CK.PROFILO
|
|
-- M.PROFILO_ASS=CK.PROFILO
|
|
LEFT OUTER JOIN
|
|
c6mart.RISCHIO_AGGREGATO RISK_AGG
|
|
ON
|
|
PATRBF.COD_FISCALE=RISK_AGG.COD_FISCALE
|
|
AND PATRBF.RETE=RISK_AGG.RETE
|
|
AND
|
|
(case when RISK_AGG.COD_AGGREG = 'COMPLESSIVO|BF' and PATRBF.RETE= 'F' then 'Patrimonio Banca Fideuram'
|
|
WHEN RISK_AGG.COD_AGGREG= 'COMPLESSIVO|BF' and PATRBF.RETE= 'S' then 'Patrimonio Sanpaolo Invest'
|
|
else 'Patrimonio altri Istituti' end)= PATRBF.INSTITUTENAME
|
|
where
|
|
(
|
|
RISK_AGG.COD_AGGREG= 'COMPL
|