You can not select more than 25 topics Topics must start with a letter or number, can include dashes ('-') and can be up to 35 characters long.
 
 
 

162 lines
7.0 KiB

USE FastMoneyPro_Remit
GO
--EXEC proc_RegulatoryReport @DATE='2019-09-20'
ALTER proc proc_RegulatoryReport
@DATE DATETIME
AS
SET NOCOUNT ON;
SET ARITHABORT ON;
DECLARE @YEARSTART VARCHAR(10),@YEAREND DATETIME,@PREVYEAR VARCHAR(10)
SELECT @PREVYEAR =CAST(YEAR(@DATE)-1 AS VARCHAR)+'-01-01',@YEARSTART = CAST(YEAR(@DATE) AS VARCHAR)+'-01-01',@YEAREND = @DATE +' 23:59:59'
--drop table #TEMP
select sbranch [Handling branch]
,[TransferDel] = '1',r.cancelApprovedDate
,r.id [SerialNo],1 [formOfRemit]
,r.createdDate [remitDT]
,collCurr,tAmt [RemittanceAmt],sCurrCostRate+ISNULL(sCurrHoMargin,0) [USDExRate]
,[RemitUSDAmt] = CAST(tAmt/(sCurrCostRate+ISNULL(sCurrHoMargin,0)) AS DECIMAL(16,2))
,serviceCharge,senderName = left(senderName,60)
,[SenderVerificationType] = s.idType
,[SenderVerificationNum] = s.idNumber
,[customerUniqueno] = s.customerId
,receiverName = LEFT(r.receiverName,60),CM.countryCode [BeneficiaryCountry]
,c.countryCode,s.customerId
INTO #TEMP
from remitTran r(nolock)
INNER join tranSenders s (nolock) on s.tranId = r.Id
LEFT JOIN countryMaster C(NOLOCK) ON C.countryName = S.nativeCountry
LEFT JOIN countryMaster CM (NOLOCK) ON CM.COUNTRYNAME = R.pCountry
where 1=1 AND tranType <> 'R'
AND (r.createdDate between @DATE and @DATE+' 23:59:59' OR r.cancelApprovedDate between @DATE and @DATE+' 23:59:59')
--and s.customerId = 38700
ALTER TABLE #TEMP ADD [zipcode] VARCHAR(20),[SumUSDAmt] DECIMAL(16,2)
DELETE FROM #TEMP WHERE FORMAT([remitDT],'yyyyMMdd') = FORMAT(ISNULL(cancelApprovedDate,'2000-01-01'),'yyyyMMdd')
UPDATE #TEMP SET cancelApprovedDate = NULL WHERE FORMAT(cancelApprovedDate,'yyyyMMdd') > @DATE
UPDATE t set t.[zipcode] = 'A' + RIGHT('000000'+CAST(m.swiftCode AS VARCHAR(6)),6) FROM #TEMP T
INNER JOIN agentMaster m(nolock) on m.agentId = t.[Handling branch]
---- TO GET SUM OF USDAMT
--SELECT [SumUSDAmt] = ROUND(SUM(tAmt/(sCurrCostRate+ISNULL(sCurrHoMargin,0))),2),s.customerId
--INTO #PREVIOUSYEAR_SUM
--FROM #TEMP T
--INNER JOIN tranSenders s (NOLOCK) ON s.customerId = t.customerId
--INNER JOIN remitTran r(NOLOCK) ON r.id = s.tranId
--WHERE t.cancelApprovedDate BETWEEN @DATE and @YEAREND
--AND t.remitDT BETWEEN @PREVYEAR AND @YEARSTART
--and r.createdDate BETWEEN @PREVYEAR AND @YEARSTART
--AND R.tranStatus <>'CANCEL'
----and s.customerId = 30278
--GROUP BY s.customerId
--select * from #TEMP
--select * from #PREVIOUSYEAR_SUM
--drop table #PREVIOUSYEAR_SUM
--drop table #THISYEAR_SUM
--select * from #PREVIOUSYEAR_SUM
--select * from #TEMP where customerId = 30278
---- ONLY FOR THIS YEAR
SELECT ROUND(sum(tAmt/(sCurrCostRate+ISNULL(sCurrHoMargin,0))),2) SumUSDAmt,s.customerId--,r.createdDate,r.cancelApprovedDate,r.id
INTO #THISYEAR_SUM
FROM remitTran r(NOLOCK)
INNER JOIN tranSenders s (NOLOCK) ON s.tranId = r.Id
WHERE r.createdDate BETWEEN @YEARSTART and @YEAREND
--AND R.tranStatus <>'CANCEL'
--and s.customerId = 30278
GROUP BY s.customerId
SELECT ROUND(sum(tAmt/(sCurrCostRate+ISNULL(sCurrHoMargin,0))),2) SumUSDAmt,s.customerId--,r.createdDate,r.cancelApprovedDate,r.id
INTO #THISYEAR_SUMCANCEL
FROM remitTran r(NOLOCK)
INNER JOIN tranSenders s (NOLOCK) ON s.tranId = r.Id
WHERE r.cancelApprovedDate BETWEEN @YEARSTART and @YEAREND
AND r.createdDate BETWEEN @YEARSTART and @YEAREND
AND R.tranStatus ='CANCEL'
--and s.customerId = 30278
GROUP BY s.customerId
UPDATE T SET T.SumUSDAmt=T.SumUSDAmt-C.SumUSDAmt FROM #THISYEAR_SUM T
INNER JOIN #THISYEAR_SUMCANCEL C ON C.customerId=T.customerId
--SELECT ROUND(sum(tAmt/(sCurrCostRate+ISNULL(sCurrHoMargin,0))),2) SumUSDAmt,s.customerId--,r.createdDate,r.cancelApprovedDate,r.id
--INTO #THISYEAR_SUM
--FROM remitTran r(NOLOCK)
--INNER JOIN tranSenders s (NOLOCK) ON s.tranId = r.Id
--INNER JOIN (
--select distinct customerId from #TEMP where remitDT BETWEEN @YEARSTART and @YEAREND
--)t ON t.customerId = s.customerId --and t.SerialNo=s.tranId
--WHERE r.createdDate BETWEEN @YEARSTART and @YEAREND
----AND R.tranStatus <>'CANCEL'
----and s.customerId = 30278
--GROUP BY s.customer
--select * from #THISYEAR_SUM
--UPDATE T SET T.SumUSDAmt = P.SumUSDAmt FROM #TEMP T
--INNER JOIN #PREVIOUSYEAR_SUM P ON P.customerId = T.customerId
--WHERE T.cancelApprovedDate BETWEEN @YEARSTART AND @YEAREND
--AND T.remitDT BETWEEN @PREVYEAR AND @YEARSTART
UPDATE T SET T.SumUSDAmt = P.SumUSDAmt FROM #TEMP T
INNER JOIN #THISYEAR_SUM P ON P.customerId = T.customerId
WHERE T.remitDT BETWEEN @YEARSTART AND @YEAREND
AND T.SumUSDAmt IS NULL
----IF TOTAL USD AMOUNT IS NULL MEANS TOTAL SEND - CANCEL =0
UPDATE #TEMP SET SumUSDAmt = 0 WHERE SumUSDAmt IS NULL
--DELETE FROM #TEMPSUM_USD WHERE FORMAT(createdDate,'yyyyMMdd') = FORMAT(ISNULL(cancelApprovedDate,'2000-01-01'),'yyyyMMdd')
---- CHECK WHETHER FIRST TIME TXN CUSTOMER EXIST OR NOT
SELECT MIN(createdDate) createdDate,MIN(TRANID) TRANID,S.customerId
INTO #TEMPCUSTOMER FROM remitTran(NOLOCK) r
INNER JOIN tranSenders s (NOLOCK) ON s.tranId = r.id
WHERE R.createdDate BETWEEN DATEADD(DAY,-5,@DATE) AND DATEADD(DAY,1,@DATE)
GROUP BY S.customerId
IF EXISTS( SELECT TOP 1 'A' FROM #TEMP C LEFT JOIN TBL_BOK_ReportingCustomerDetail T(NOLOCK) ON T.customerId = C.customerId WHERE T.customerId IS NULL)
BEGIN
DELETE C FROM #TEMPCUSTOMER C
INNER JOIN TBL_BOK_ReportingCustomerDetail T ON T.customerId=C.customerId
INSERT INTO TBL_BOK_ReportingCustomerDetail(customerId,firstTranId,firstTranDate,idType,idNumber,createdDate,createdBy)
select DISTINCT C.customerId,T.TRANID,C.createdDate,T.idType,T.idNumber,GETDATE(),'system' FROM #TEMPCUSTOMER C
INNER JOIN tranSenders(NOLOCK) T ON T.tranId=C.tranId
ORDER BY C.customerId,TRANID
END
---- update customer id type and number base on customer first time txn
UPDATE C SET C.SenderVerificationNum = T.idNumber,C.SenderVerificationType = T.idType
FROM #TEMP C
INNER JOIN TBL_BOK_ReportingCustomerDetail T ON T.customerId=C.customerId
SELECT [Handling branch],[zipcode]
,[TransferDel] = CASE WHEN FORMAT(ISNULL(cancelApprovedDate,'2200-01-01'),'yyyyMMdd') >FORMAT(CAST(@DATE AS DATE),'yyyyMMdd') THEN '1' ELSE '2' END
,[SerialNo],[formOfRemit]
,[remitDT] = FORMAT([remitDT],'yyyyMMdd')
,[remitTime] = 'H' + RIGHT('000000'+CAST(FORMAT(remitDT,'HHmmss') AS VARCHAR(6)),6)
,collCurr,[RemittanceAmt],[USDExRate],[RemitUSDAmt]
,serviceCharge,senderName
,[SenderVerificationType] = CASE
WHEN LEN(REPLACE(SenderVerificationNum, '-', '')) <> '13' THEN '99'
WHEN LEFT(RIGHT(REPLACE(SenderVerificationNum, '-', ''), 7), 1) = '0' OR customerUniqueno = 98526 THEN 'P02'
WHEN LEFT(RIGHT(REPLACE(SenderVerificationNum, '-', ''), 7), 1) IN ('1', '2', '3', '4') THEN 'P01'
WHEN
LEFT(RIGHT(REPLACE(SenderVerificationNum, '-', ''), 7), 1) IN ('5', '6') THEN 'P04'
ELSE '99'
END
,[SenderVerificationNum] = replace(SenderVerificationNum,'-','')
,[SenderCountry] = CASE WHEN SenderVerificationType IN ('Alien Registration Card','National ID') AND LEFT(RIGHT(REPLACE(SenderVerificationNum, '-', ''), 7), 1) IN ('1', '2', '3', '4') THEN 'KR' ELSE countryCode END
,[SumUSDAmt],[customerUniqueno],receiverName,[BeneficiaryCountry]
FROM(
SELECT * FROM #TEMP
)X
ORDER BY [customerUniqueno],[SerialNo], [TransferDel]