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

110 lines
3.9 KiB
Transact-SQL

-- Schema: C6MartPeriodico
-- Stored Procedure: DM_PATRIMONIO_EMITTENTI
-- =============================================
-- Author: <Alessandro Tringali>
-- Create date: <Create Date,,>
-- Description: <Description,,>
-- =============================================
CREATE procedure [C6MartPeriodico].[DM_PATRIMONIO_EMITTENTI]
AS
BEGIN
-- SET NOCOUNT ON added to prevent extra result sets from
-- interfering with SELECT statements.
SET NOCOUNT ON;
SET NOCOUNT ON;
DECLARE @ID_ELAB INT
DECLARE @TIPO_ELAB VARCHAR(1)
SET @ID_ELAB = C6MartPeriodico.GETIDELAB()
SET @TIPO_ELAB = C6MartPeriodico.GETTIPOELAB()
-- Log esecuzione
INSERT INTO LOG_ESECUZIONE_PERIODICO
(Nome, Inizio, Nota)
VALUES (
'DM_PATRIMONIO_EMITTENTI',
GETDATE(),
'Elaborazione trimestrale'
)
TRUNCATE TABLE C6MartPeriodico.PATRIMONIO_EMITTENTI
INSERT INTO
[C6MARTPERIODICO].[PATRIMONIO_EMITTENTI]
(
COD_FISCALE,
RETE,
POSITION_ID,
COD_PRODOTTO,
COD_ADEGUATEZZA,
INTERMEDIARIO,
CTV_INTERMEDIARIO,
CTV_INTER_NOCC_NEG,
EMITTENTE,
COMPLESSITA,
CTV_EMITTENTE,
CTV_PRODOTTO,
FLG_AZ_OB,
CREDITRISKCLASS,
CTV_AZIONARIO,
CTV_OBBLIGAZIONARIO,
CTV_AZ_OB_EMIT,
CTV_AZ_OB_EMIT_INTER,
CTV_COMPLESSIVO,
CTV_COMPL_NOCC_NEG,
CONC_EMITTENTE,
CONC_EMIT_INTERM,
COPERTURA
)
SELECT H.COD_FISCALE,
H.RETE,
H.POSITION_ID,
H.COD_PRODOTTO AS CATALOGUENAME,
'' AS COD_ADEGUATEZZA,
'BF' AS INTERMEDIARIO,
sum(h.ctv) over (partition by h.cod_fiscale, h.rete) AS PATRIMONIO_INTERMEDIARIO,
sum(case when h.tipo_prodotto='CC' and h.ctv < 0 then 0 else h.ctv END ) over (partition by h.cod_fiscale, h.rete) AS PATRIMONIO_INTER_nocc_neg,
H.EMITTENTE,
H.COMPLEX AS COMPLESSITA,
sum(h.ctv) over (partition by h.cod_fiscale, H.rete, H.EMITTENTE) AS PATRIMONIO_EMITTENTE,
h.ctv as CONTROVALORE_PRODOTTO,
CASE WHEN H.STRTYPE IN ('AZ', 'OB') THEN H.STRTYPE ELSE NULL END AS AZ_OB,
K.classe AS CREDITRISKCLASS,
SUM( case when STRTYPE = 'AZ' then h.ctv else 0 end ) OVER( PARTITION BY H.COD_FISCALE,H.RETE,EMITTENTE, H.POSITION_ID) AS CTV_AZIONARIO,
SUM(case when STRTYPE = 'OB' then h.ctv else 0 end ) OVER( PARTITION BY H.COD_FISCALE,H.RETE,EMITTENTE, H.POSITION_ID) AS CTV_OBBLIGAZIONARIO,
SUM( case when STRTYPE IN ( 'AZ','OB') then h.ctv else 0 end ) OVER( PARTITION BY H.COD_FISCALE,H.RETE,EMITTENTE) PATRIMONIO_AZ_OB_EMIT,
SUM( case when STRTYPE IN ( 'AZ','OB') then h.ctv else 0 end ) OVER( PARTITION BY H.COd_FISCALE,H.RETE,EMITTENTE) PATRIM_AZ_OB_EMIT_INTER,
sum(case when h.tipo_prodotto='CC' and h.ctv < 0 then 0 else h.ctv END) over (partition by h.cod_fiscale, h.rete) as PATRIMONIO_COMPLESSIVO,
sum(case when h.tipo_prodotto='CC' and h.ctv < 0 then 0 else h.ctv END) over (partition by h.cod_fiscale, h.rete) as PATRIMONIO_COMPL_nocc_neg,
0 as concentrazione_emittente,
0 AS concentraz_emit_interm,
r.copertura
FROM C6MARTPERIODICO.PATRIMONIO_BF H
LEFT OUTER join
C6MARTPERIODICO.RISCHIO_AGGREGATO R
on
H.COD_FISCALE=R.COD_FISCALE
AND H.RETE=R.RETE
AND r.COD_AGGREG =
((CASE
WHEN (h.NOME_PROGETTO IS NOT NULL)
THEN 'RISFIN|PIRAMIDE|' + LEFT(h.ID_AREA,3) + '|' + h.NOME_PROGETTO+ '|'+ isnull(cast(H.ordinamento_progetto as varchar),'')+'|'
ELSE
CASE WHEN (h.ID_AREA = 'NA') THEN 'RISFIN|' + LEFT(h.ID_AREA,3) + '|'
ELSE 'RISFIN|PIRAMIDE|' + LEFT(h.ID_AREA,3) + '|'
END
END)
+ h.POSITION_ID)
left outer join