151 lines
8.5 KiB
SQL
151 lines
8.5 KiB
SQL
CREATE VIEW [C6MartPeriodico].[vTabellone]
|
|
AS
|
|
select a.chiaveClientePB as ChiaveClientePB
|
|
,a.rete as Rete
|
|
,a.cod_fiscale as Chiave_ACN
|
|
,case when a.TIP_CONTRATTO=3 then 'DIRECT ADVISORY' else 'SEI' end as Tipo_Cliente
|
|
,case when len(a.COD_FISCALE)=16 then a.COD_FISCALE else '' end as Codice_Fiscale
|
|
,case when a.COD_FISCALE like '%FF@%' then a.PIVA_FIDUCIARIA when len(a.COD_FISCALE)<16 then a.COD_FISCALE else '' end as Partita_Iva
|
|
,a.COD_MANDATO as Codice_Mandato
|
|
,a.codiceContratto as Codice_Contratto
|
|
,case when isnull(cli.nome,'')<>'' and LEN(a.COD_FISCALE)<16 then '' else isnull(cli.nome,'') end as Nome_Cliente
|
|
,case when isnull(cli.nome,'')<>'' and LEN(a.COD_FISCALE)<16 then isnull(cli.cognome,'')+isnull(cli.nome,'') else isnull(cli.cognome,'') end as Cognome_Cliente
|
|
,isnull(cli.dtnascita,'') as Data_Nascita_Cliente
|
|
,a.INDIRIZZO as Indirizzo
|
|
,isnull(a.cap,'00000') as Cap
|
|
,a.CITTA as Citta
|
|
,a.PROVINCIA as Provincia
|
|
,a.NAZIONE as Nazione
|
|
,COD_AGENTE as Agente
|
|
,pb.Nome as Nome_Agente
|
|
,pb.Cognome as Cognome_Agente
|
|
,'SI' as Report_Monitoraggio
|
|
,case when a.FREQ_DIAGNOSI<>'' then 'SI' else 'NO' end as Report_Diagnosi
|
|
,a.Data_FineAvanzato as Data_Revoca
|
|
,case when a.TIP_CONTRATTO=2 then 'SI' else 'NO' end as Flag_Private
|
|
,case when v.tipoconsulenza='P' then 'SI' else 'NO' end as Flag_Professionale
|
|
,benv.Data_Lettera_Benvenuto as Data_Lettera_Benvenuto
|
|
,case when isnull(cam.cod_fiscale,'')=cam.cod_fiscale then 'SI' else 'NO' end as Campione_SEI
|
|
,case when isnull(camDA.cod_fiscale,'')=camDA.cod_fiscale then 'SI' else 'NO' end as Campione_DA
|
|
,case when ISNULL(ps.cod_fiscale,'')=ps.Cod_fiscale OR ISNULL(dc.cod_fiscale,'')=dc.Cod_fiscale then 'SI' else 'NO' end as Lettera_Sostitutiva
|
|
,case when isnull(exc.codicefiscale,'')=exc.codicefiscale then 'SI' else 'NO' end as Blacklist_Temporanea
|
|
,isnull(exc.descrerr,'') as Motivazione_Blacklist
|
|
,isnull(pdf.NomeFile,'NON GENERATO') as Nome_PDF_Monitoraggio
|
|
,isnull(pdfd.NomeFile,'NON GENERATO')+'_DP' as Nome_PDF_Diagnosi
|
|
,isnull(zip.nomefile+'_LOTTO_'+rtrim(cast(zip.fkidelaborazionezip as char))+'_PACK_'+rtrim(cast(zip.id as char))+'.7z','NON ZIPPATO') as Nome_Zip
|
|
,ISNULL(rol.statorol,'NO') as Rol
|
|
,case when stab.ESG='S' then 'SI' else 'NO' end as Preferenza_ESG--case when esg.preferenza_esg_cliente=1 then 'SI' else 'NO' end as Preferenza_ESG
|
|
,isnull(esg.ESG_E,stab.Environmental) as ESG_E
|
|
,isnull(esg.ESG_S,stab.Social) as ESG_S
|
|
,isnull(esg.ESG_G,stab.Governance) as ESG_G
|
|
,CASE
|
|
WHEN esg.[ESG_E_perc] IS NOT NULL AND esg.[ESG_S_perc] IS NOT NULL AND esg.[ESG_G_perc] IS NOT NULL THEN
|
|
CASE
|
|
WHEN esg.[ESG_E_perc] >= esg.[ESG_S_perc] AND esg.[ESG_E_perc] >= esg.[ESG_G_perc] THEN esg.[ESG_E_perc]
|
|
WHEN esg.[ESG_S_perc] >= esg.[ESG_E_perc] AND esg.[ESG_S_perc] >= esg.[ESG_G_perc] THEN esg.[ESG_S_perc]
|
|
ELSE esg.[ESG_G_perc]
|
|
END
|
|
ELSE
|
|
CASE
|
|
WHEN stab.[ESG_E_perc] >= stab.[ESG_S_perc] AND stab.[ESG_E_perc] >= stab.[ESG_G_perc] THEN stab.[ESG_E_perc]
|
|
WHEN stab.[ESG_S_perc] >= stab.[ESG_E_perc] AND stab.[ESG_S_perc] >= stab.[ESG_G_perc] THEN stab.[ESG_S_perc]
|
|
ELSE stab.[ESG_G_perc]
|
|
END
|
|
END as obiettivo_esg_minimo
|
|
,isnull(esg.ESG_E_perc,stab.ESG_E_perc) as ESG_E_perc
|
|
,isnull(esg.ESG_S_perc,stab.ESG_S_perc) as ESG_S_perc
|
|
,isnull(esg.ESG_G_perc,stab.ESG_G_perc) as ESG_G_perc
|
|
,an2.[CODPROF] as Codice_Profilo
|
|
,an2.[COD_PROFEC] as Codice_Profilo_EC
|
|
,case when isnull(stab.ade_rischio_mercato,'NO')='1' THEN 'S' else 'N' end as Rischio
|
|
,an2.[RISERVA] as Riserva
|
|
,an2.[INVL_PERIOD] as Investimento_Di_Lungo_Periodo
|
|
,an2.[CLCOMPL] as Complessita
|
|
,an2.[FLGCONC] as Concentrazione_di_prodotti_complessi
|
|
,an2.[FREQ] as Frequenza_delle_operazioni
|
|
,an2.[CONCEMI] as Concentrazione_Emittenti
|
|
,an2.[FLAGPG] as Persona_Giuridica
|
|
,an2.[ADEGCONC_VALUT] as Concentrazione_Valutaria
|
|
,an2.[COERENZA] as Esito_di_Coerenza
|
|
,an2.[FLAGNQP]
|
|
,an2.[FLGPRLRDE] as Flag_Privo_di_Legali_Rappresentanti_Delegati_Profilati
|
|
--,an2.[FLGPROF]
|
|
,an2.[SOGLIAESG] as Soglia_ESG
|
|
,an2.[MAXCOMPL] as Max_Complessita_Prodotto
|
|
,an2.[NOCOMPL]
|
|
,an2.[SPESA_FORZATA] as Spesa_Forzata
|
|
,an2.[PERC_ILP] as Percentuale_Investimento_di_lungo_periodo
|
|
,an2.[IMP_RISERVA] as Importo_Riserva
|
|
,case when isnull(imm.CODFIS,'')=imm.codfis then 'SI' else 'NO' end as Immobiliare
|
|
,case when isnull(imm.CODFIS,'')=imm.codfis and imm.RENDICONTO_IMM='S' then 'SI' else 'NO' end as Solo_Immobiliare
|
|
,stab.var_portafoglio as VaR_Portafoglio
|
|
,stab.corfa_rfa as RFA--,isnull(w.Patrimoniobancafideuramctv,stab.corfa_rfa) as RFA
|
|
,case
|
|
when ISNULL(ps.cod_fiscale,'')=ps.Cod_fiscale OR ISNULL(dc1.cod_fiscale,'')=dc1.Cod_fiscale then 'SCADUTO'
|
|
when mif.scaduto='0' then 'ATTIVO'
|
|
when mif.scaduto='1' then 'SCADUTO'
|
|
when mif.scaduto='2' then 'PARZIALE' else 'ATTIVO' end as Tipo_Scaduto
|
|
FROM [C6StampeCentralizzate].[C6StagingPeriodico].[APPO_CONTRATTI] a
|
|
left join consuni_periodico.ConsulenzaUnica.dbo.vinfocliente v
|
|
on a.chiaveClientePB=v.chiaveclientePB
|
|
left join consuni_periodico.ConsulenzaUnica.dbo.Cliente cli
|
|
on v.chiavecliente=cli.chiavecliente
|
|
left join (
|
|
SELECT rete,codicefiscale, Max(DataGenerazione) as Data_Lettera_Benvenuto
|
|
FROM C6Mart.gestione_pdf_ftp
|
|
GROUP BY rete,codicefiscale
|
|
) benv
|
|
on a.rete=benv.Rete and a.COD_FISCALE=benv.CodiceFiscale
|
|
left join C6MartPeriodico.TB_Campione cam on
|
|
a.rete=cam.Rete and a.COD_FISCALE=cam.Cod_Fiscale
|
|
left join C6MartPeriodico.TB_Campione_DA camDA on
|
|
a.rete=camDA.Rete and a.COD_FISCALE=camDA.Cod_Fiscale
|
|
left join (select rete,case when codman<>'' then 'FF@'+codman else codfis end as Cod_fiscale from C6StagingPeriodico.WSEIPS where DTTRIM=[C6MartPeriodico].[getTrimestre2](getdate(),0) ) ps
|
|
on ps.RETE=a.rete and a.COD_FISCALE=ps.Cod_fiscale
|
|
left join (select rete,case when codman<>'' then 'FF@'+codman else codfis end as Cod_fiscale from C6StagingPeriodico.WSEIDC where DTTRIM=[C6MartPeriodico].[getTrimestre2](getdate(),0) ) dc
|
|
on dc.RETE=a.rete and a.COD_FISCALE=dc.Cod_fiscale
|
|
left join (select distinct rete,codicefiscale,STRING_AGG( ISNULL(DescrErr, ' '), ',') As descrerr from C6MartPeriodico.ExcludedList group by rete,codicefiscale) exc
|
|
on exc.RETE=a.rete and a.COD_FISCALE=exc.codicefiscale
|
|
left join (select * from c6martperiodico.gestione_pdf_ftp where TipoReport='M') pdf
|
|
on pdf.rete=a.rete and a.cod_fiscale=pdf.codicefiscale
|
|
left join c6martperiodico.gestione_zip_ftp zip
|
|
on pdf.id_fk_zip=zip.id
|
|
left join (select * from c6martperiodico.gestione_pdf_ftp where TipoReport='D') pdfD
|
|
on pdfD.rete=a.rete and a.cod_fiscale=pdfD.codicefiscale
|
|
left join C6StagingPeriodico.datiROL2 rol on
|
|
a.rete=rol.Rete and a.COD_FISCALE=rol.CODFIS
|
|
left join [CONSUNI_periodico].ConsulenzaUnica.dbo.anagrafica_promotori pb
|
|
on a.rete = pb.rete and a.COD_AGENTE=pb.codage
|
|
left join (select Rete,case when codman<>'' then 'FF@'+codman else CodiceFiscale end as Cod_fiscale,preferenza_esg_cliente,ESG_E,ESG_S,ESG_G,obiettivo_ESG_minimo,ESG_E_perc,ESG_S_perc,ESG_G_perc from [C6StagingPeriodico].[ESG_Metriche_Cliente_IL] where trim(CONVERT(varchar, dt_trim, 112))=[C6MartPeriodico].[getTrimestre2](getdate(),0)) esg
|
|
on esg.RETE=a.rete and a.COD_FISCALE=esg.Cod_fiscale
|
|
left join
|
|
(select [RETE]
|
|
,case when codman<>'' then 'FF@'+codman else codfis end as Cod_fiscale
|
|
,[CODPROF]
|
|
,[COD_PROFEC]
|
|
,[FLAGPG]
|
|
,[CLCOMPL]
|
|
,[FLGCONC]
|
|
,[FLAGNQP]
|
|
,[FLGPRLRDE]
|
|
,[FLGPROF]
|
|
,[CONCEMI]
|
|
,[FREQ]
|
|
,[ADEGCONC_VALUT]
|
|
,[SOGLIAESG]
|
|
,[COERENZA]
|
|
,[RISERVA]
|
|
,[INVL_PERIOD]
|
|
,[MAXCOMPL]
|
|
,[NOCOMPL]
|
|
,[SPESA_FORZATA]
|
|
,[PERC_ILP]
|
|
,[IMP_RISERVA] from [C6StampeCentralizzate].[C6StagingPeriodico].[WSEIAN2] where DTTRIM=[C6MartPeriodico].[getTrimestre2](getdate(),0)) an2
|
|
on a.rete=an2.Rete and a.COD_FISCALE=an2.Cod_Fiscale
|
|
left join C6MartPeriodicoImmobiliare.W6IMM imm --where FLAG_IN_PERIMETRO='S' and RENDICONTO_IMM='S'
|
|
on a.rete=imm.RETE and a.COD_FISCALE=imm.CODFIS
|
|
left join (select * from C6MartPeriodico.tabellone where DTTRIM=[C6MartPeriodico].[getTrimestre2](getdate(),0)) stab on stab.chiave_acn= a.rete+a.COD_FISCALE
|
|
left join wh.Maledetti w on w.rete+w.CodiceFiscale=a.rete+a.COD_FISCALE
|
|
left join C6MartPeriodico.Mifid mif on mif.RETE+mif.COD_FISCALE=a.rete+a.COD_FISCALE
|
|
left join (select rete,case when codman<>'' then 'FF@'+codman else codfis end as Cod_fiscale from C6StagingPeriodico.WSEIDC where DTTRIM=[C6MartPeriodico].[getTrimestre2](getdate(),0) and TIPOLETT not in ('R','S') ) dc1
|
|
on dc1.RETE=a.rete and a.COD_FISCALE=dc1.Cod_fiscale |