221 lines
6.5 KiB
Transact-SQL
221 lines
6.5 KiB
Transact-SQL
-- =============================================
|
|
-- Author: Paolo Giovanetti / TRINGALI PER FIDUCIARIE
|
|
-- Create date: <Create Date,,>
|
|
-- Description: <Description,,>
|
|
-- =============================================
|
|
CREATE procedure [C6MartPeriodico].[DM_ANAG_CLIENTI]
|
|
AS
|
|
BEGIN
|
|
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
|
|
(Nome, Inizio, Nota)
|
|
VALUES (
|
|
'DM_ANAG_CLIENTI',
|
|
GETDATE(),
|
|
'Elaborazione trimestrale'
|
|
)
|
|
TRUNCATE TABLE C6MartPeriodico.ANAG_CLIENTI
|
|
INSERT INTO C6MartPeriodico.[ANAG_CLIENTI]
|
|
([RETE]
|
|
,[COD_FISCALE]
|
|
,[NOME]
|
|
,[COGNOME]
|
|
,[DATA_NASCITA]
|
|
,[STATO_CIVILE]
|
|
,[NUM_COMPONENTI]
|
|
,[NUM_FIGLI]
|
|
,[ETA]
|
|
,[PARTITA_IVA]
|
|
,[CITTADINANZA]
|
|
,[PERSONA_FIS_GIUR]
|
|
,[INDIRIZZO]
|
|
,[LOCALITA]
|
|
,[PROVINCIA]
|
|
,[CAP]
|
|
,[NAZIONE]
|
|
,[PRESSO]
|
|
,[TEL_RECAPITO]
|
|
,[TEL_CELL]
|
|
,[E_MAIL]
|
|
,[DATA_INIZIO]
|
|
,[DATA_FINE]
|
|
,[STATO]
|
|
,[RAG_SOC]
|
|
,[SESSO]
|
|
,[ID_PROMOTORE]
|
|
,[ID_ELAB]
|
|
,[TIPO_ELAB])
|
|
SELECT
|
|
AL.RETE_PB AS RETE,
|
|
AL.CODICEFISCALE AS COD_FISCALE,
|
|
RTRIM(ISNULL(CL.NOME,AL.NOME)) AS NOME,
|
|
RTRIM(ISNULL(CL.COGNOME,AL.COGNOME)) AS COGNOME,
|
|
ISNULL(
|
|
AL.DATA_NASCITA,
|
|
CASE
|
|
WHEN ISDATE(CL.DTNASCI) = 0 THEN NULL
|
|
ELSE CAST(CAST(CL.DTNASCI AS VARCHAR(8)) AS DATETIME)
|
|
END) AS DATA_NASCITA,
|
|
CASE
|
|
WHEN SUBSTRING(AL.CODICE_FISCALE,10,2) < '40'
|
|
AND AL.MARITALSTATUS = 'Married' THEN 'Coniugato'
|
|
WHEN SUBSTRING(AL.CODICE_FISCALE,10,2) < '40'
|
|
AND AL.MARITALSTATUS = 'Divorced' THEN 'Divorziato'
|
|
WHEN SUBSTRING(AL.CODICE_FISCALE,10,2) < '40'
|
|
AND AL.MARITALSTATUS = 'Single' THEN 'Libero'
|
|
WHEN SUBSTRING(AL.CODICE_FISCALE,10,2) > '40'
|
|
AND AL.MARITALSTATUS = 'Married' THEN 'Coniugata'
|
|
WHEN SUBSTRING(AL.CODICE_FISCALE,10,2) > '40'
|
|
AND AL.MARITALSTATUS = 'Divorced' THEN 'Divorziata'
|
|
WHEN SUBSTRING(AL.CODICE_FISCALE,10,2) > '40'
|
|
AND AL.MARITALSTATUS = 'Single' THEN 'Libera'
|
|
ELSE NULL
|
|
END AS STATO_CIVILE,
|
|
NULL AS NUM_COMPONENTI,
|
|
NULL AS NUM_FIGLI,
|
|
/*DATEDIFF(YY,
|
|
ISNULL(
|
|
AL.DATA_NASCITA,
|
|
CASE
|
|
WHEN ISDATE(CL.DTNASCI) = 0 THEN NULL
|
|
ELSE CAST(CAST(CL.DTNASCI AS VARCHAR(8)) AS DATETIME)
|
|
END),
|
|
GETDATE()) AS ETA,*/
|
|
dbo.Eta(ISNULL(
|
|
AL.DATA_NASCITA,
|
|
CASE
|
|
WHEN ISDATE(CL.DTNASCI) = 0 THEN NULL
|
|
ELSE CAST(CAST(CL.DTNASCI AS VARCHAR(8)) AS DATETIME)
|
|
END)
|
|
) AS ETA,
|
|
NULL AS PARTITA_IVA,
|
|
NULL AS CITTADINANZA,
|
|
NULL AS PERSONA_FIS_GIUR,
|
|
ISNULL(CL.INDIRIZZO, '') AS INDIRIZZO,
|
|
ISNULL(CL.CITTA, '') AS LOCALITA,
|
|
ISNULL(CL.PROVINCIA, '') AS PROVINCIA,
|
|
ISNULL(CL.CAP, '') AS CAP,
|
|
ISNULL(CL.NAZIONE, '') AS NAZIONE,
|
|
'' AS PRESSO,
|
|
NULL AS TEL_RECAPITO,
|
|
NULL AS TEL_CELL,
|
|
NULL AS E_MAIL,
|
|
NULL AS DATA_INIZIO,
|
|
NULL AS DATA_FINE,
|
|
NULL AS STATO,
|
|
NULL AS RAG_SOC,
|
|
--NULL AS SESSO,
|
|
CASE
|
|
WHEN SUBSTRING(AL.CODICE_FISCALE,10,2) < '40' THEN 'M'
|
|
ELSE 'F'
|
|
END AS SESSO,
|
|
AL.CODICE_PB AS ID_PROMOTORE,
|
|
@ID_ELAB AS ID_ELAB,
|
|
@TIPO_ELAB AS TIPO_ELAB
|
|
FROM C6STAGINGPERIODICO.ALL_CF_PB AL
|
|
LEFT JOIN C6STAGINGPERIODICO.WSEIAN2 CL
|
|
ON CL.RETE = AL.RETE_PB
|
|
AND ( ltrim(rtrim(CL.CODFIS)) = AL.CODICEFISCALE)
|
|
WHERE CL.DTTRIM = (
|
|
SELECT MAX(DTTRIM)
|
|
FROM C6StagingPeriodico.WSEIAN2
|
|
) and Al.codicefiscale not like '%@%'
|
|
union
|
|
SELECT
|
|
AL.RETE_PB AS RETE,
|
|
AL.CODICEFISCALE AS COD_FISCALE,
|
|
RTRIM(ISNULL(CL.NOME,AL.NOME)) AS NOME,
|
|
RTRIM(ISNULL(CL.COGNOME,AL.COGNOME)) AS COGNOME,
|
|
ISNULL(
|
|
AL.DATA_NASCITA,
|
|
CASE
|
|
WHEN ISDATE(CL.DTNASCI) = 0 THEN NULL
|
|
ELSE CAST(CAST(CL.DTNASCI AS VARCHAR(8)) AS DATETIME)
|
|
END) AS DATA_NASCITA,
|
|
CASE
|
|
WHEN SUBSTRING(AL.CODICE_FISCALE,10,2) < '40'
|
|
AND AL.MARITALSTATUS = 'Married' THEN 'Coniugato'
|
|
WHEN SUBSTRING(AL.CODICE_FISCALE,10,2) < '40'
|
|
AND AL.MARITALSTATUS = 'Divorced' THEN 'Divorziato'
|
|
WHEN SUBSTRING(AL.CODICE_FISCALE,10,2) < '40'
|
|
AND AL.MARITALSTATUS = 'Single' THEN 'Libero'
|
|
WHEN SUBSTRING(AL.CODICE_FISCALE,10,2) > '40'
|
|
AND AL.MARITALSTATUS = 'Married' THEN 'Coniugata'
|
|
WHEN SUBSTRING(AL.CODICE_FISCALE,10,2) > '40'
|
|
AND AL.MARITALSTATUS = 'Divorced' THEN 'Divorziata'
|
|
WHEN SUBSTRING(AL.CODICE_FISCALE,10,2) > '40'
|
|
AND AL.MARITALSTATUS = 'Single' THEN 'Libera'
|
|
ELSE NULL
|
|
END AS STATO_CIVILE,
|
|
NULL AS NUM_COMPONENTI,
|
|
NULL AS NUM_FIGLI,
|
|
/*DATEDIFF(YY,
|
|
ISNULL(
|
|
AL.DATA_NASCITA,
|
|
CASE
|
|
WHEN ISDATE(CL.DTNASCI) = 0 THEN NULL
|
|
ELSE CAST(CAST(CL.DTNASCI AS VARCHAR(8)) AS DATETIME)
|
|
END),
|
|
GETDATE()) AS ETA,*/
|
|
dbo.Eta(ISNULL(
|
|
AL.DATA_NASCITA,
|
|
CASE
|
|
WHEN ISDATE(CL.DTNASCI) = 0 THEN NULL
|
|
ELSE CAST(CAST(CL.DTNASCI AS VARCHAR(8)) AS DATETIME)
|
|
END)
|
|
) AS ETA,
|
|
NULL AS PARTITA_IVA,
|
|
NULL AS CITTADINANZA,
|
|
NULL AS PERSONA_FIS_GIUR,
|
|
ISNULL(CL.INDIRIZZO, '') AS INDIRIZZO,
|
|
ISNULL(CL.CITTA, '') AS LOCALITA,
|
|
ISNULL(CL.PROVINCIA, '') AS PROVINCIA,
|
|
ISNULL(CL.CAP, '') AS CAP,
|
|
ISNULL(CL.NAZIONE, '') AS NAZIONE,
|
|
'' AS PRESSO,
|
|
NULL AS TEL_RECAPITO,
|
|
NULL AS TEL_CELL,
|
|
NULL AS E_MAIL,
|
|
NULL AS DATA_INIZIO,
|
|
NULL AS DATA_FINE,
|
|
NULL AS STATO,
|
|
NULL AS RAG_SOC,
|
|
--NULL AS SESSO,
|
|
CASE
|
|
WHEN SUBSTRING(AL.CODICE_FISCALE,10,2) < '40' THEN 'M'
|
|
ELSE 'F'
|
|
END AS SESSO,
|
|
AL.CODICE_PB AS ID_PROMOTORE ,
|
|
@ID_ELAB AS ID_ELAB,
|
|
@TIPO_ELAB AS TIPO_ELAB
|
|
FROM C6STAGINGPERIODICO.ALL_CF_PB AL
|
|
LEFT JOIN C6STAGINGPERIODICO.WSEIAN2 CL
|
|
ON CL.RETE = AL.RETE_PB
|
|
AND ( CL.CODMAN = substring(AL.CODICEFISCALE,4,4))
|
|
WHERE CL.DTTRIM = (
|
|
SELECT MAX(DTTRIM)
|
|
FROM C6StagingPeriodico.WSEIAN2
|
|
) and Al.codicefiscale like '%@%'
|
|
-- Log esecuzione
|
|
UPDATE
|
|
LOG_ESECUZIONE
|
|
SET
|
|
Fine = GETDATE(),
|
|
Tipo = 'INSERT',
|
|
Righe = @@ROWCOUNT
|
|
WHERE
|
|
Nome = 'DM_ANAG_CLIENTI' AND
|
|
Inizio = (
|
|
SELECT
|
|
MAX(Inizio)
|
|
FROM
|
|
LOG_ESECUZIONE
|
|
WHERE
|
|
Nome = 'DM_ANAG_CLIENTI'
|
|
)
|
|
END |