249 lines
7.0 KiB
Transact-SQL
249 lines
7.0 KiB
Transact-SQL
CREATE procedure [dbo].[test_S80All_fc]
|
|
AS
|
|
BEGIN
|
|
/*
|
|
Purpose: Calculate the total quantity and sales of the product in
|
|
product wise.
|
|
Input : No input specified. It will calculate for all the products
|
|
in Product Master table.
|
|
Output : ProductID,ProductName,Total Quantity and Grand Total of
|
|
sale.
|
|
Method : The report generated without using the Cursor
|
|
-----------------------------------------------------------------------
|
|
********************* Modification History *************************
|
|
-----------------------------------------------------------------------
|
|
S.No Name Date Version
|
|
-----------------------------------------------------------------------
|
|
1. Erode Senthilkumar Sep 01, 2009 1.0
|
|
-----------------------------------------------------------------------
|
|
*/
|
|
SET NOCOUNT ON
|
|
SET XACT_ABORT ON
|
|
DECLARE @ProductID INT
|
|
DECLARE @ProductName VARCHAR(100)
|
|
DECLARE @TotalQty INT
|
|
DECLARE @Total MONEY
|
|
DECLARE @Index INT
|
|
DECLARE @RecordCnt INT
|
|
DECLARE @tab TABLE(
|
|
id INT IDENTITY(1,1)
|
|
,rete char(1)
|
|
,codicefiscale varchar(16)
|
|
,totCC int
|
|
,totNoCC int
|
|
)
|
|
DECLARE @testTab TABLE
|
|
(
|
|
id INT IDENTITY(1,1)
|
|
,rete char(1)
|
|
,codicefiscale VARCHAR(100)
|
|
,CountCC INT
|
|
,CountNoCC int
|
|
)
|
|
DECLARE @Rete char(1)
|
|
DECLARE @CodiceFiscale varchar(16)
|
|
-- Recupero data congelamento SEI
|
|
DECLARE @MONIT_INIT INT
|
|
DECLARE @DataCongelamento DATETIME
|
|
DECLARE @MONIT_ATTIV INT
|
|
DECLARE @AGGR INT
|
|
declare @contaCC as int
|
|
declare @contapos as int
|
|
SET @DataCongelamento = C6MartPeriodico.getDataCongelamento()
|
|
SET @MONIT_ATTIV=0
|
|
SET @MONIT_INIT = 0
|
|
SELECT @Index = 1
|
|
INSERT INTO @tab(rete,codicefiscale,totCC,totNoCC)
|
|
select rete,cod_fiscale
|
|
,sum ( case when tipo_prodotto ='CC' then tot else 0 end ) as cc
|
|
,sum ( case when tipo_prodotto <>'CC' then tot else 0 end ) as nocc
|
|
from
|
|
( select rete,cod_fiscale,tipo_prodotto,count(*) tot
|
|
from c6martperiodico.patrimonio_Bf
|
|
--where cod_fiscale = @codiceFiscale and rete = @rete
|
|
group by rete,cod_fiscale,tipo_prodotto
|
|
) as gr
|
|
group by rete,cod_fiscale
|
|
SELECT @RecordCnt = COUNT(id) FROM @tab
|
|
WHILE (@Index <= @RecordCnt)
|
|
BEGIN
|
|
SELECT @rete=rete
|
|
,@codicefiscale=codicefiscale
|
|
,@contacc=totCC
|
|
,@contapos=totNoCC
|
|
FROM @tab WHERE id = @Index
|
|
SELECT @MONIT_INIT = COUNT(*)
|
|
FROM
|
|
C6MARTPERIODICO.MONITORAGGIO_INIZIALE
|
|
WHERE
|
|
RETE = @Rete AND
|
|
COD_FISCALE = @CodiceFiscale
|
|
SELECT @MONIT_ATTIV=COUNT(*)
|
|
FROM
|
|
C6MARTPERIODICO.MONITORAGGIO_ATTUALE
|
|
WHERE
|
|
RETE = @Rete AND
|
|
COD_FISCALE = @CodiceFiscale
|
|
SELECT @AGGR=COUNT(*)
|
|
FROM
|
|
C6MARTPERIODICO.RISCHIO_AGGREGATO
|
|
WHERE
|
|
RETE = @Rete AND
|
|
COD_FISCALE = @CodiceFiscale
|
|
IF (@MONIT_ATTIV > 0 AND @AGGR > 0 AND @MONIT_INIT > 0)
|
|
BEGIN
|
|
-- Attivazione monitoraggio
|
|
-- nuova versione da testare
|
|
insert into c6martperiodico.tb_S80BisEvoluzioneRischio
|
|
SELECT
|
|
@rete,
|
|
@codicefiscale,
|
|
1 AS Fase,
|
|
INI.DATA_FOTO AS DataFase,
|
|
INI.VAR_MAX_PROFILO AS VarMassimoProfiloFinanziario,
|
|
--V
|
|
CASE
|
|
WHEN INI.VAR_COMPLESSIVO IS NULL THEN INI.VAR_COMPLESSIVO
|
|
ELSE ROUND(INI.VAR_COMPLESSIVO,2)
|
|
END AS VarComplessivo,
|
|
INI.VAR_COPERTURA AS Copertura,
|
|
INI.RISKCLASS,
|
|
INI.RISKCLASSMAX,
|
|
case
|
|
when INI.RISKCLASS is null then 'n.d.'
|
|
when INI.RISKCLASS = 0 then 'n.a.'
|
|
else null
|
|
end as RiskClassString,
|
|
case
|
|
when INI.RISKCLASSMAX is null then 'n.d.'
|
|
when INI.RISKCLASSMAX = 0 then 'n.a.'
|
|
else null
|
|
end as RiskClassMaxString
|
|
FROM
|
|
C6MartPeriodico.MONITORAGGIO_INIZIALE INI
|
|
LEFT OUTER join
|
|
C6MartPeriodico.MONITORAGGIO_REPORT rep
|
|
on
|
|
REP.RETE=INI.RETE
|
|
AND
|
|
REP.COD_FISCALE=INI.COD_FISCALE
|
|
WHERE
|
|
INI.RETE = @Rete AND
|
|
INI.COD_FISCALE = @CodiceFiscale
|
|
-- SELECT
|
|
-- 1 AS Fase,
|
|
-- INI.DATA_FOTO AS DataFase,
|
|
-- INI.VAR_MAX_PROFILO AS VarMassimoProfiloFinanziario,
|
|
-- --V
|
|
-- CASE
|
|
-- WHEN INI.VAR_COMPLESSIVO IS NULL THEN INI.VAR_COMPLESSIVO
|
|
-- ELSE ROUND(INI.VAR_COMPLESSIVO,2)
|
|
-- END AS VarComplessivo,
|
|
-- INI.VAR_COPERTURA AS Copertura
|
|
-- FROM
|
|
-- C6MartPeriodico.MONITORAGGIO_INIZIALE INI
|
|
--
|
|
-- WHERE
|
|
-- INI.RETE = @Rete AND
|
|
-- INI.COD_FISCALE = @CodiceFiscale
|
|
UNION ALL
|
|
-- Precedente invio report
|
|
SELECT
|
|
@rete,
|
|
@codicefiscale,
|
|
2 AS Fase,
|
|
rep.DATA_INVIO AS DataFase,
|
|
rep.VAR_MAX_PROFILO AS VarMassimoProfiloFinanziario,
|
|
--V
|
|
CASE
|
|
WHEN rep.VAR_COMPLESSIVO IS NULL THEN rep.VAR_COMPLESSIVO
|
|
ELSE ROUND(rep.VAR_COMPLESSIVO,2)
|
|
END AS VarComplessivo,
|
|
rep.VAR_COPERTURA AS Copertura,
|
|
rep.RISKCLASS,
|
|
rep.RISKCLASSMAX,
|
|
case when rep.RISKCLASS is null then 'n.a.'
|
|
else null
|
|
end as RiskClassString,
|
|
case when rep.RISKCLASSMAX is null then 'n.a.'
|
|
else null
|
|
end as RiskClassMaxString
|
|
FROM
|
|
C6MartPeriodico.MONITORAGGIO_INIZIALE INI
|
|
left outer join
|
|
C6MartPeriodico.MONITORAGGIO_REPORT rep
|
|
on
|
|
REP.RETE=INI.RETE
|
|
AND
|
|
REP.COD_FISCALE=INI.COD_FISCALE
|
|
WHERE
|
|
rep.RETE = @Rete AND
|
|
rep.COD_FISCALE = @CodiceFiscale
|
|
AND INI.DATA_FOTO < ISNULL(REP.DATA_INVIO,cast('29991231' as datetime))
|
|
and ISNULL(DATA_INVIO,cast('29991231' as datetime))<@datacongelamento
|
|
UNION ALL
|
|
-- Situazione corrente
|
|
SELECT
|
|
@rete,
|
|
@codicefiscale,
|
|
3 fase,
|
|
CASE
|
|
WHEN @DataCongelamento IS NULL THEN GETDATE()
|
|
ELSE @DataCongelamento
|
|
END AS DataFase,
|
|
CR.MAX_VAR AS VarMassimoProfiloFinanziario,
|
|
--V
|
|
CASE WHEN RA.VAR_PERC_PTF IS NULL THEN 0.00
|
|
ELSE ROUND(RA.VAR_PERC_PTF,2)
|
|
END AS VarComplessivo,
|
|
CASE
|
|
WHEN (@contaPOS - @contaCC = 0 ) THEN 100
|
|
ELSE isnull(RA.COPERTURA,0)
|
|
END AS Copertura,
|
|
-- TRINGALI MODIFICARE
|
|
ra.creditrisk as RISKCLASS,
|
|
mifid.riskclass as RISKCLASSMAX,
|
|
case when ra.creditrisk is null then 'n.a.'
|
|
else null end as RiskClassString,
|
|
case when mifid.riskclass is null then 'n.a.'
|
|
else null end as RiskClassMaxString
|
|
FROM
|
|
C6MartPeriodico.vPatrimonioBFAggregato AS BF
|
|
INNER JOIN C6MartPeriodico.MIFID AS MIFID
|
|
ON BF.RETE = MIFID.RETE
|
|
AND BF.COD_FISCALE = MIFID.COD_FISCALE
|
|
INNER JOIN C6MartPeriodico.CODIFICA_RISCHIO AS CR
|
|
ON MIFID.PROFILO_ASS = CR.PROFILO
|
|
LEFT OUTER JOIN C6MartPeriodico.RISCHIO_AGGREGATO AS RA
|
|
ON RA.RETE = BF.RETE
|
|
AND RA.COD_FISCALE = BF.COD_FISCALE
|
|
AND RA.COD_AGGREG = 'COMPLESSIVO|BF'
|
|
WHERE
|
|
BF.RETE = @Rete AND
|
|
BF.COD_FISCALE = @CodiceFiscale
|
|
END
|
|
ELSE
|
|
BEGIN
|
|
insert into c6martperiodico.tb_S80BisEvoluzioneRischio
|
|
( rete,codicefiscale,fase,datafase,VarMassimoProfiloFinanziario,VarComplessivo,Copertura)
|
|
SELECT
|
|
@rete,
|
|
@codicefiscale,
|
|
2 AS Fase,
|
|
DATA_INVIO AS DataFase,
|
|
VAR_MAX_PROFILO AS VarMassimoProfiloFinanziario,
|
|
--V
|
|
CASE
|
|
WHEN VAR_COMPLESSIVO IS NULL THEN VAR_COMPLESSIVO
|
|
ELSE ROUND(VAR_COMPLESSIVO,2)
|
|
END AS VarComplessivo,
|
|
VAR_COPERTURA AS Copertura
|
|
FROM
|
|
C6MartPeriodico.MONITORAGGIO_REPORT
|
|
WHERE
|
|
1=2
|
|
END
|
|
SELECT @Index = @Index + 1
|
|
END
|
|
SELECT count(*) FROM @testTab
|
|
END |