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.

903 lines
48 KiB

  1. --WARNING! ERRORS ENCOUNTERED DURING SQL PARSING!
  2. USE [FastMoneyPro_Remit]
  3. GO
  4. /****** Object: StoredProcedure [dbo].[PROC_COMPLIANCE_CHECKING_NEW] Script Date: 8/21/2023 3:45:45 PM ******/
  5. SET ANSI_NULLS ON
  6. GO
  7. SET QUOTED_IDENTIFIER ON
  8. GO
  9. ALTER PROC [dbo].[PROC_COMPLIANCE_CHECKING_NEW] (
  10. @flag VARCHAR(30) = 'core'
  11. ,@user VARCHAR(50)
  12. ,@pCountryId INT
  13. ,@deliveryMethod INT
  14. ,@amount MONEY = NULL
  15. ,@customerId VARCHAR(20)
  16. ,@receiverName VARCHAR(50) = NULL
  17. ,@sIdNo VARCHAR(50) = NULL
  18. ,@sIdType VARCHAR(50) = NULL
  19. ,@receiverMobile VARCHAR(25) = NULL
  20. ,@message VARCHAR(1000) = NULL
  21. ,@shortMessage VARCHAR(100) = NULL
  22. ,@errCode TINYINT = NULL
  23. ,@ruleId INT = NULL
  24. ,@professionId INT = NULL
  25. ,@accountNo VARCHAR(30) = NULL
  26. ,@receiverId BIGINT = NULL
  27. ,@sNaCountryId INT = NULL
  28. ,@visaStatus INT = NULL
  29. )
  30. AS
  31. SET NOCOUNT ON;
  32. SET XACT_ABORT ON;
  33. BEGIN
  34. DECLARE @perTxnLimitAmt MONEY
  35. DECLARE @limitAmt MONEY
  36. ,@comRuleId INT
  37. ,@ruleType CHAR(1)
  38. ,@periodInDays INT
  39. ,@isDocRequired BIT
  40. DECLARE @limitAmtAgg MONEY
  41. ,@comRuleIdAgg INT
  42. ,@ruleTypeAgg CHAR(1)
  43. ,@sNativeCountry VARCHAR(100)
  44. DECLARE @limitAmtProfession MONEY
  45. ,@comRuleIdProfession INT
  46. ,@ruleTypeProfession CHAR(1)
  47. DECLARE @csMasterId INT
  48. ,@rCountry VARCHAR(50)
  49. ,@rCountryName VARCHAR(100)
  50. DECLARE @YearStart DATE
  51. ,@YearEnd DATE
  52. ,@MonthStart DATE
  53. ,@MonthEnd DATE
  54. CREATE TABLE #TBL_COMPLIANCE (
  55. COMM_RULE_ID INT
  56. ,LIMIT_AMT MONEY
  57. ,RULE_TYPE CHAR(1)
  58. ,PERIOD_DAYS INT
  59. ,R_COUNNTRY INT
  60. ,PAYMENT_MODE INT
  61. ,IS_CHECKED BIT
  62. ,IS_DOC_REQUIRED BIT
  63. ,RULE_SPECIFIC_TYPE VARCHAR(100)
  64. ,RULE_SPECIFIC_NAME VARCHAR(100)
  65. )
  66. CREATE TABLE #TBL_COMPLIANCE_RECEIVER (
  67. COMM_RULE_ID INT
  68. ,LIMIT_AMT MONEY
  69. ,RULE_TYPE CHAR(1)
  70. ,PERIOD_DAYS INT
  71. ,R_COUNNTRY INT
  72. ,PAYMENT_MODE INT
  73. ,IS_CHECKED BIT
  74. ,IS_DOC_REQUIRED BIT
  75. )
  76. CREATE TABLE #TBL_COMPLIANCE_NO_OF_TXN (
  77. CONDITION INT
  78. ,COMM_RULE_ID INT
  79. ,LIMIT_NO_OF_TXN INT
  80. ,RULE_TYPE CHAR(1)
  81. ,PERIOD_DAYS INT
  82. ,R_COUNNTRY INT
  83. ,PAYMENT_MODE INT
  84. ,IS_CHECKED BIT
  85. ,IS_DOC_REQUIRED BIT
  86. )
  87. SELECT @YearStart = DATEADD(DAY, - 365, GETDATE())
  88. ,@MonthStart = DATEADD(DAY, - 30, GETDATE())
  89. INSERT INTO #TBL_COMPLIANCE (
  90. COMM_RULE_ID
  91. ,LIMIT_AMT
  92. ,RULE_TYPE
  93. ,R_COUNNTRY
  94. ,PERIOD_DAYS
  95. ,PAYMENT_MODE
  96. ,IS_CHECKED
  97. ,IS_DOC_REQUIRED
  98. ,RULE_SPECIFIC_TYPE
  99. ,RULE_SPECIFIC_NAME
  100. )
  101. SELECT comRuleId = comRuleId
  102. ,limitAmt = limitAmt
  103. ,ruleType = nextAction
  104. ,rCountry
  105. ,period
  106. ,paymentMode
  107. ,0
  108. ,documentRequired
  109. ,RULE_SPECIFIC_TYPE
  110. ,RULE_SPECIFIC_NAME
  111. FROM (
  112. --SELECT comRuleId = csDetailId, limitAmt = amount, CD.nextAction, CM.rCountry, CD.period, CD.paymentMode, CD.documentRequired, NULL RULE_SPECIFIC_TYPE, NULL RULE_SPECIFIC_NAME
  113. --FROM dbo.csDetail CD(NOLOCK)
  114. --INNER JOIN csMaster CM(NOLOCK) ON CM.csMasterId = CD.csMasterId
  115. --WHERE ISNULL(CM.rCountry, @pCountryId) = @pCountryId
  116. --AND CD.condition in (11446)
  117. --AND ISNULL(CD.paymentMode, @deliveryMethod) = @deliveryMethod
  118. --AND ISNULL(CD.isActive, 'Y') = 'Y'
  119. --AND ISNULL(CD.isDeleted, 'N') = 'N'
  120. --AND ISNULL(CD.isEnable, 'Y') = 'Y'
  121. --AND ISNULL(CM.isActive, 'Y') = 'Y'
  122. --AND ISNULL(CM.isDeleted, 'N') = 'N'
  123. --AND PROFESSION IS NULL
  124. --UNION ALL
  125. SELECT comRuleId = csDetailId
  126. ,limitAmt = amount
  127. ,CD.nextAction
  128. ,CM.rCountry
  129. ,CD.period
  130. ,CD.paymentMode
  131. ,CD.documentRequired
  132. ,NULL RULE_SPECIFIC_TYPE
  133. ,NULL RULE_SPECIFIC_NAME
  134. FROM dbo.csDetail CD(NOLOCK)
  135. INNER JOIN csMaster CM(NOLOCK) ON CM.csMasterId = CD.csMasterId
  136. WHERE ISNULL(CM.rCountry, @pCountryId) = @pCountryId
  137. AND CD.condition IN (4600)
  138. AND ISNULL(CD.paymentMode, @deliveryMethod) = @deliveryMethod
  139. AND ISNULL(CD.isActive, 'Y') = 'Y'
  140. AND ISNULL(CD.isDeleted, 'N') = 'N'
  141. AND ISNULL(CD.isEnable, 'Y') = 'Y'
  142. AND ISNULL(CM.isActive, 'Y') = 'Y'
  143. AND ISNULL(CM.isDeleted, 'N') = 'N'
  144. AND PROFESSION IS NULL
  145. UNION ALL
  146. SELECT comRuleId = csDetailId
  147. ,limitAmt = amount
  148. ,CD.nextAction
  149. ,CM.rCountry
  150. ,CD.period
  151. ,CD.paymentMode
  152. ,CD.documentRequired
  153. ,' Profession ' RULE_SPECIFIC_TYPE
  154. ,SV.detailTitle RULE_SPECIFIC_NAME
  155. FROM dbo.csDetail CD(NOLOCK)
  156. LEFT JOIN staticDataValue SV(NOLOCK) ON SV.valueId = CD.profession
  157. INNER JOIN csMaster CM(NOLOCK) ON CM.csMasterId = CD.csMasterId
  158. WHERE ISNULL(CM.rCountry, @pCountryId) = @pCountryId
  159. AND CD.condition IN (11201)
  160. AND ISNULL(CD.paymentMode, @deliveryMethod) = @deliveryMethod
  161. AND ISNULL(CD.isActive, 'Y') = 'Y'
  162. AND ISNULL(CD.isDeleted, 'N') = 'N'
  163. AND ISNULL(CD.isEnable, 'Y') = 'Y'
  164. AND ISNULL(CM.isActive, 'Y') = 'Y'
  165. AND ISNULL(CM.isDeleted, 'N') = 'N'
  166. AND PROFESSION = @professionId
  167. UNION ALL
  168. SELECT comRuleId = csDetailId
  169. ,limitAmt = amount
  170. ,CD.nextAction
  171. ,CM.rCountry
  172. ,CD.period
  173. ,CD.paymentMode
  174. ,CD.documentRequired
  175. ,' Visa Status ' RULE_SPECIFIC_TYPE
  176. ,SV.detailTitle RULE_SPECIFIC_NAME
  177. FROM dbo.csDetail CD(NOLOCK)
  178. LEFT JOIN staticDataValue SV(NOLOCK) ON SV.valueId = CD.visaStatus
  179. INNER JOIN csMaster CM(NOLOCK) ON CM.csMasterId = CD.csMasterId
  180. WHERE ISNULL(CM.rCountry, @pCountryId) = @pCountryId
  181. AND CD.condition IN (11403)
  182. AND ISNULL(CD.paymentMode, @deliveryMethod) = @deliveryMethod
  183. AND ISNULL(CD.isActive, 'Y') = 'Y'
  184. AND ISNULL(CD.isDeleted, 'N') = 'N'
  185. AND ISNULL(CD.isEnable, 'Y') = 'Y'
  186. AND ISNULL(CM.isActive, 'Y') = 'Y'
  187. AND ISNULL(CM.isDeleted, 'N') = 'N'
  188. AND VISASTATUS = @visaStatus
  189. UNION ALL
  190. SELECT comRuleId = csDetailId
  191. ,limitAmt = amount
  192. ,CD.nextAction
  193. ,CM.rCountry
  194. ,CD.period
  195. ,CD.paymentMode
  196. ,CD.documentRequired
  197. ,' Sender Nationality ' RULE_SPECIFIC_TYPE
  198. ,CMS.countryName RULE_SPECIFIC_NAME
  199. FROM dbo.csDetail CD(NOLOCK)
  200. LEFT JOIN countryMaster CMS(NOLOCK) ON CMS.countryId = CD.profession
  201. INNER JOIN csMaster CM(NOLOCK) ON CM.csMasterId = CD.csMasterId
  202. WHERE ISNULL(CM.rCountry, @pCountryId) = @pCountryId
  203. AND CD.condition IN (11384)
  204. AND ISNULL(CD.paymentMode, @deliveryMethod) = @deliveryMethod
  205. AND ISNULL(CD.isActive, 'Y') = 'Y'
  206. AND ISNULL(CD.isDeleted, 'N') = 'N'
  207. AND ISNULL(CD.isEnable, 'Y') = 'Y'
  208. AND ISNULL(CM.isActive, 'Y') = 'Y'
  209. AND ISNULL(CM.isDeleted, 'N') = 'N'
  210. AND PROFESSION = @sNaCountryId
  211. ) X;
  212. --DELETE RECORD HAVING SAME PERIOD(PER TXN, 1 DAY, 30 DAY) AND RULE TYPE(HOLD, BLOCK) AND CHOOSE SMALLER AMOUNT
  213. WITH CTE
  214. AS (
  215. SELECT ROW_NUMBER() OVER (
  216. PARTITION BY RULE_TYPE
  217. ,PERIOD_DAYS
  218. ,COMM_RULE_ID ORDER BY LIMIT_AMT ASC
  219. ) ROW_ID
  220. ,*
  221. FROM #TBL_COMPLIANCE
  222. )
  223. DELETE
  224. FROM CTE
  225. WHERE ROW_ID = 2
  226. --select * from #TBL_COMPLIANCE
  227. --return
  228. CREATE TABLE #tempTran (
  229. id BIGINT
  230. ,tAmt MONEY
  231. ,sIdType VARCHAR(100)
  232. ,sIdNo VARCHAR(100)
  233. ,createdDate DATETIME
  234. ,tranStatus VARCHAR(50)
  235. )
  236. CREATE TABLE #tempTranR (
  237. id BIGINT
  238. ,tAmt MONEY
  239. ,createdDate DATETIME
  240. ,tranStatus VARCHAR(50)
  241. ,receiverName VARCHAR(150)
  242. )
  243. DECLARE @sumTxnAmt MONEY
  244. ,@maxDays INT
  245. SELECT @maxDays = MAX(PERIOD_DAYS)
  246. FROM #TBL_COMPLIANCE
  247. INSERT INTO #tempTran (
  248. id
  249. ,tAmt
  250. ,sIdType
  251. ,sIdNo
  252. ,createdDate
  253. ,tranStatus
  254. )
  255. SELECT r.id
  256. ,r.tAmt
  257. ,s.idType
  258. ,s.idNumber
  259. ,r.createdDate
  260. ,r.tranStatus
  261. FROM vwRemitTran R(NOLOCK)
  262. INNER JOIN vwtranSenders S(NOLOCK) ON R.ID = S.tranId
  263. WHERE r.tranStatus <> 'Cancel'
  264. AND S.customerId = @customerId
  265. AND r.createdDate BETWEEN DATEADD(DAY, - 1 * @maxDays, CAST(GETDATE() AS DATE))
  266. AND GETDATE()
  267. CREATE TABLE #TBL_COMPLIANCE_RESULT (
  268. ERROR_CODE INT
  269. ,MSG VARCHAR(500)
  270. ,RULE_ID INT
  271. ,SHORT_MSG VARCHAR(100)
  272. ,[TYPE] VARCHAR(10)
  273. ,IS_DOC_REQUIRED BIT
  274. )
  275. --SELECT * FROM #TBL_COMPLIANCE --WHERE RULE_TYPE = 'B'
  276. WHILE EXISTS (
  277. SELECT TOP 1 1
  278. FROM #TBL_COMPLIANCE
  279. WHERE IS_CHECKED = 0
  280. )
  281. BEGIN
  282. DECLARE @RULE_SPECIFIC VARCHAR(200)
  283. SET @rCountryName = NULL
  284. SELECT @limitAmt = LIMIT_AMT
  285. ,@comRuleId = COMM_RULE_ID
  286. ,@ruleType = RULE_TYPE
  287. ,@periodInDays = PERIOD_DAYS
  288. ,@isDocRequired = IS_DOC_REQUIRED
  289. ,@rCountry = R_COUNNTRY
  290. ,@RULE_SPECIFIC = RULE_SPECIFIC_TYPE + ': ' + RULE_SPECIFIC_NAME
  291. FROM #TBL_COMPLIANCE
  292. WHERE IS_CHECKED = 0
  293. --AND RULE_TYPE = 'B'
  294. ORDER BY PERIOD_DAYS DESC
  295. IF @rCountry IS NOT NULL
  296. SELECT @rCountryName = countryName
  297. FROM countryMaster(NOLOCK)
  298. WHERE COUNTRYID = @rCountry
  299. IF @periodInDays <> 0
  300. SELECT @sumTxnAmt = SUM(ISNULL(tAmt, 0))
  301. FROM #tempTran
  302. WHERE createdDate BETWEEN DATEADD(DAY, CASE
  303. WHEN @periodInDays = 1
  304. THEN 0
  305. ELSE - 1 * @periodInDays
  306. END, CAST(GETDATE() AS DATE))
  307. AND GETDATE()
  308. ELSE
  309. SET @sumTxnAmt = 0
  310. IF (ISNULL(@sumTxnAmt, 0) + @amount) > @limitAmt
  311. BEGIN
  312. SET @message = CASE
  313. WHEN @periodInDays = 0
  314. THEN 'The transaction is
  315. <b style=''background-color:red; color:white;''>' + CASE
  316. WHEN @ruleType = 'B'
  317. THEN 'blocked'
  318. WHEN @ruleType = 'Q'
  319. THEN 'questionnaire'
  320. ELSE 'hold'
  321. END + '</b> because the transaction
  322. amount (<b>' + CAST(@amount AS VARCHAR) + ' JPY</b>), is exceeded as <b>per transaction</b> Limit (<b>' + CAST(@limitAmt AS VARCHAR) + ' JPY</b>).' + ISNULL('Receiving country Limit: ' + @rCountryName, '') + ISNULL(@RULE_SPECIFIC, '')
  323. ELSE 'The transaction is
  324. <b style=''background-color:red; color:white;''>' + CASE
  325. WHEN @ruleType = 'B'
  326. THEN 'blocked'
  327. WHEN @ruleType = 'Q'
  328. THEN 'questionnaire'
  329. ELSE 'hold'
  330. END + '</b> because previous transaction sum is
  331. (<b>' + CAST(ISNULL(@sumTxnAmt, 0) AS VARCHAR) + ' JPY</b>) and by doing this transaction (<b>' + CAST(@amount AS VARCHAR) + ' JPY</b>)
  332. <b>' + CAST(@periodInDays AS VARCHAR) + ' Day(s) transaction</b> Limit (<b>' + CAST(@limitAmt AS VARCHAR) + ' JPY</b>) is exceeded.' + ISNULL('Receiving country Limit: ' + @rCountryName, '') + ISNULL(@RULE_SPECIFIC, '')
  333. END
  334. INSERT INTO #TBL_COMPLIANCE_RESULT
  335. SELECT CASE
  336. WHEN @ruleType = 'B'
  337. THEN 1
  338. WHEN @ruleType = 'H'
  339. THEN 2
  340. ELSE 3
  341. END
  342. ,@message
  343. ,@comRuleId
  344. ,CASE
  345. WHEN @periodInDays = 0
  346. THEN 'Per txn limit exceeded'
  347. ELSE CAST(@periodInDays AS VARCHAR) + ' Day(s) txn limit exceeded.'
  348. END
  349. ,'SENDER'
  350. ,@isDocRequired
  351. END
  352. UPDATE #TBL_COMPLIANCE
  353. SET IS_CHECKED = 1
  354. WHERE COMM_RULE_ID = @comRuleId
  355. END
  356. IF EXISTS (
  357. SELECT *
  358. FROM #TBL_COMPLIANCE_RESULT
  359. WHERE ERROR_CODE = 1
  360. )
  361. BEGIN
  362. SELECT *
  363. FROM #TBL_COMPLIANCE_RESULT
  364. RETURN
  365. END
  366. --Check for receiver
  367. IF ISNULL(@receiverName, '') = ''
  368. BEGIN
  369. SELECT @errCode = 0
  370. ,@message = 'Success'
  371. ,@ruleId = 0
  372. RETURN
  373. END
  374. INSERT INTO #TBL_COMPLIANCE_RECEIVER (
  375. COMM_RULE_ID
  376. ,LIMIT_AMT
  377. ,RULE_TYPE
  378. ,R_COUNNTRY
  379. ,PERIOD_DAYS
  380. ,PAYMENT_MODE
  381. ,IS_CHECKED
  382. ,IS_DOC_REQUIRED
  383. )
  384. SELECT comRuleId = comRuleId
  385. ,limitAmt = limitAmt
  386. ,ruleType = nextAction
  387. ,rCountry
  388. ,period
  389. ,paymentMode
  390. ,0
  391. ,documentRequired
  392. FROM (
  393. SELECT comRuleId = csDetailId
  394. ,limitAmt = amount
  395. ,CD.nextAction
  396. ,CM.rCountry
  397. ,CD.period
  398. ,CD.paymentMode
  399. ,CD.documentRequired
  400. FROM dbo.csDetail CD(NOLOCK)
  401. INNER JOIN csMaster CM(NOLOCK) ON CM.csMasterId = CD.csMasterId
  402. WHERE ISNULL(CM.rCountry, @pCountryId) = @pCountryId
  403. AND CD.condition IN (4603)
  404. AND ISNULL(CD.paymentMode, @deliveryMethod) = @deliveryMethod
  405. AND ISNULL(CD.isActive, 'Y') = 'Y'
  406. AND ISNULL(CD.isDeleted, 'N') = 'N'
  407. AND ISNULL(CD.isEnable, 'Y') = 'Y'
  408. AND ISNULL(CM.isActive, 'Y') = 'Y'
  409. AND ISNULL(CM.isDeleted, 'N') = 'N'
  410. ) X;
  411. --DELETE RECORD HAVING SAME PERIOD(PER TXN, 1 DAY, 30 DAY) AND RULE TYPE(HOLD, BLOCK) AND CHOOSE SMALLER AMOUNT
  412. WITH CTE1
  413. AS (
  414. SELECT ROW_NUMBER() OVER (
  415. PARTITION BY RULE_TYPE
  416. ,PERIOD_DAYS ORDER BY LIMIT_AMT ASC
  417. ) ROW_ID
  418. ,*
  419. FROM #TBL_COMPLIANCE_RECEIVER
  420. )
  421. DELETE
  422. FROM CTE1
  423. WHERE ROW_ID = 2
  424. SELECT @maxDays = MAX(PERIOD_DAYS)
  425. FROM #TBL_COMPLIANCE_RECEIVER
  426. SET @receiverMobile = '%' + @receiverMobile
  427. --IF ISNULL(@accountNo, '') = ''
  428. -- SELECT @accountNo = receiverAccountNo FROM RECEIVERINFORMATION (NOLOCK) WHERE RECEIVERID = @receiverId
  429. INSERT INTO #tempTranR (
  430. id
  431. ,tAmt
  432. ,receiverName
  433. ,createdDate
  434. ,tranStatus
  435. )
  436. SELECT rt.id
  437. ,tAmt
  438. ,tr.firstName
  439. ,createdDate
  440. ,tranStatus
  441. FROM vwRemitTran rt WITH (NOLOCK)
  442. INNER JOIN dbo.vwTranReceivers tr WITH (NOLOCK) ON tr.tranId = rt.id
  443. WHERE tr.fullName = @receiverName
  444. AND tranStatus <> 'CANCEL'
  445. AND TR.mobile LIKE @receiverMobile
  446. AND createdDate BETWEEN DATEADD(DAY, - 1 * @maxDays, CAST(GETDATE() AS DATE))
  447. AND GETDATE()
  448. --AND RT.paymentMethod <> 'BANK DEPOSIT'
  449. --UNION ALL
  450. --SELECT rt.id,tAmt,tr.firstName,createdDate,tranStatus
  451. --FROM vwRemitTran rt WITH(NOLOCK)
  452. --INNER JOIN dbo.vwTranReceivers tr WITH(NOLOCK) ON tr.tranId = rt.id
  453. --WHERE tranStatus <> 'CANCEL'
  454. --AND rt.ACCOUNTNO = @accountNo
  455. --AND createdDate BETWEEN DATEADD(DAY, -1 * @maxDays, GETDATE()) AND GETDATE()
  456. --AND RT.paymentMethod = 'BANK DEPOSIT'
  457. WHILE EXISTS (
  458. SELECT TOP 1 1
  459. FROM #TBL_COMPLIANCE_RECEIVER
  460. WHERE IS_CHECKED = 0
  461. )
  462. BEGIN
  463. SET @rCountryName = NULL
  464. SELECT @limitAmt = LIMIT_AMT
  465. ,@comRuleId = COMM_RULE_ID
  466. ,@ruleType = RULE_TYPE
  467. ,@periodInDays = PERIOD_DAYS
  468. ,@isDocRequired = IS_DOC_REQUIRED
  469. ,@rCountry = R_COUNNTRY
  470. FROM #TBL_COMPLIANCE_RECEIVER
  471. WHERE IS_CHECKED = 0
  472. --AND RULE_TYPE = 'B'
  473. ORDER BY PERIOD_DAYS DESC
  474. IF @periodInDays <> 0
  475. SELECT @sumTxnAmt = SUM(ISNULL(tAmt, 0))
  476. FROM #tempTranR
  477. WHERE createdDate BETWEEN DATEADD(DAY, CASE
  478. WHEN @periodInDays = 1
  479. THEN 0
  480. ELSE - 1 * @periodInDays
  481. END, CAST(GETDATE() AS DATE))
  482. AND GETDATE()
  483. ELSE
  484. SET @sumTxnAmt = 0
  485. IF @rCountry IS NOT NULL
  486. SELECT @rCountryName = countryName
  487. FROM countryMaster(NOLOCK)
  488. WHERE COUNTRYID = @rCountry
  489. IF (ISNULL(@sumTxnAmt, 0) + @amount) > @limitAmt
  490. BEGIN
  491. SET @message = CASE
  492. WHEN @periodInDays = 0
  493. THEN 'The transaction is in <b style=''background-color:red; color:white;''>' + CASE
  494. WHEN @ruleType = 'B'
  495. THEN 'blocked'
  496. WHEN @ruleType = 'Q'
  497. THEN 'questionnaire'
  498. ELSE 'hold'
  499. END + '</b> because same reciever
  500. <b>per day transaction</b> Limit (<b>' + CAST(@limitAmt AS VARCHAR) + ' JPY</b>) is exceeded.(' + CAST((@sumTxnAmt + @amount) AS VARCHAR) + ' JPY)' + ISNULL('Receiving country Limit: ' + @rCountryName, '')
  501. ELSE 'The transaction is in<b style=''background-color:red; color:white;''>' + CASE
  502. WHEN @ruleType = 'B'
  503. THEN 'blocked'
  504. WHEN @ruleType = 'Q'
  505. THEN 'questionnaire'
  506. ELSE 'hold'
  507. END + '</b> because same reciever
  508. <b>' + CAST(@periodInDays AS VARCHAR) + ' Day(s) transaction</b> Limit (<b>' + CAST(@limitAmt AS VARCHAR) + ' JPY</b>) is exceeded.(' + CAST((ISNULL(@sumTxnAmt, 0) + @amount) AS VARCHAR) + ' JPY)' + ISNULL('Receiving country Limit: ' + @rCountryName, '')
  509. END
  510. INSERT INTO #TBL_COMPLIANCE_RESULT
  511. SELECT CASE
  512. WHEN @ruleType = 'B'
  513. THEN 1
  514. WHEN @ruleType = 'H'
  515. THEN 2
  516. ELSE 3
  517. END
  518. ,@message
  519. ,@comRuleId
  520. ,CASE
  521. WHEN @periodInDays = 0
  522. THEN 'Per txn limit exceeded'
  523. ELSE CAST(@periodInDays AS VARCHAR) + ' Day(s) txn limit exceeded.'
  524. END
  525. ,'RECEIVER'
  526. ,@isDocRequired
  527. END
  528. UPDATE #TBL_COMPLIANCE_RECEIVER
  529. SET IS_CHECKED = 1
  530. WHERE COMM_RULE_ID = @comRuleId
  531. END
  532. IF EXISTS (
  533. SELECT *
  534. FROM #TBL_COMPLIANCE_RESULT
  535. WHERE ERROR_CODE = 1
  536. )
  537. BEGIN
  538. SELECT *
  539. FROM #TBL_COMPLIANCE_RESULT
  540. RETURN
  541. END
  542. --COMPLIANCE NO OF TXN WISE
  543. INSERT INTO #TBL_COMPLIANCE_NO_OF_TXN (
  544. COMM_RULE_ID
  545. ,LIMIT_NO_OF_TXN
  546. ,RULE_TYPE
  547. ,R_COUNNTRY
  548. ,PERIOD_DAYS
  549. ,PAYMENT_MODE
  550. ,IS_CHECKED
  551. ,CONDITION
  552. ,IS_DOC_REQUIRED
  553. )
  554. SELECT comRuleId = comRuleId
  555. ,limitAmt = limitAmt
  556. ,ruleType = nextAction
  557. ,rCountry
  558. ,period
  559. ,paymentMode
  560. ,0
  561. ,CONDITION
  562. ,documentRequired
  563. FROM (
  564. SELECT comRuleId = csDetailId
  565. ,limitAmt = amount
  566. ,CD.nextAction
  567. ,CM.rCountry
  568. ,CD.period
  569. ,CD.paymentMode
  570. ,CD.CONDITION
  571. ,CD.documentRequired
  572. FROM dbo.csDetail CD(NOLOCK)
  573. INNER JOIN csMaster CM(NOLOCK) ON CM.csMasterId = CD.csMasterId
  574. WHERE ISNULL(CM.rCountry, @pCountryId) = @pCountryId
  575. AND CD.condition IN (11446)
  576. AND ISNULL(CD.paymentMode, @deliveryMethod) = @deliveryMethod
  577. AND ISNULL(CD.isActive, 'Y') = 'Y'
  578. AND ISNULL(CD.isDeleted, 'N') = 'N'
  579. AND ISNULL(CD.isEnable, 'Y') = 'Y'
  580. AND ISNULL(CM.isActive, 'Y') = 'Y'
  581. AND ISNULL(CM.isDeleted, 'N') = 'N'
  582. UNION ALL
  583. SELECT comRuleId = csDetailId
  584. ,limitAmt = amount
  585. ,CD.nextAction
  586. ,CM.rCountry
  587. ,CD.period
  588. ,CD.paymentMode
  589. ,CD.CONDITION
  590. ,CD.documentRequired
  591. FROM dbo.csDetail CD(NOLOCK)
  592. INNER JOIN csMaster CM(NOLOCK) ON CM.csMasterId = CD.csMasterId
  593. WHERE ISNULL(CM.rCountry, @pCountryId) = @pCountryId
  594. AND CD.condition IN (
  595. 11311
  596. ,11312
  597. )
  598. AND ISNULL(CD.paymentMode, @deliveryMethod) = @deliveryMethod
  599. AND ISNULL(CD.isActive, 'Y') = 'Y'
  600. AND ISNULL(CD.isDeleted, 'N') = 'N'
  601. AND ISNULL(CD.isEnable, 'Y') = 'Y'
  602. AND ISNULL(CM.isActive, 'Y') = 'Y'
  603. AND ISNULL(CM.isDeleted, 'N') = 'N'
  604. ) X;
  605. --DELETE RECORD HAVING SAME PERIOD(PER TXN, 1 DAY, 30 DAY) AND RULE TYPE(HOLD, BLOCK) AND CHOOSE SMALLER AMOUNT
  606. WITH CTE2
  607. AS (
  608. SELECT ROW_NUMBER() OVER (
  609. PARTITION BY RULE_TYPE
  610. ,PERIOD_DAYS
  611. ,CONDITION ORDER BY LIMIT_NO_OF_TXN ASC
  612. ) ROW_ID
  613. ,*
  614. FROM #TBL_COMPLIANCE_NO_OF_TXN
  615. )
  616. DELETE
  617. FROM CTE2
  618. WHERE ROW_ID = 2
  619. CREATE TABLE #tempNoOfTxn (
  620. tAmt MONEY
  621. ,txnType CHAR(1)
  622. ,createdDate DATETIME
  623. )
  624. SELECT @maxDays = MAX(PERIOD_DAYS)
  625. FROM #TBL_COMPLIANCE_NO_OF_TXN
  626. INSERT INTO #tempNoOfTxn (
  627. tAmt
  628. ,txnType
  629. ,createdDate
  630. )
  631. SELECT TAMT
  632. ,'S'
  633. ,createdDate
  634. FROM vwRemitTran R(NOLOCK)
  635. INNER JOIN vwtranSenders S(NOLOCK) ON R.ID = S.tranId
  636. WHERE r.tranStatus <> 'Cancel'
  637. AND S.customerId = @customerId
  638. AND r.createdDate BETWEEN DATEADD(DAY, - 1 * @maxDays, CAST(GETDATE() AS DATE))
  639. AND GETDATE()
  640. INSERT INTO #tempNoOfTxn (
  641. tAmt
  642. ,txnType
  643. ,createdDate
  644. )
  645. SELECT TAMT
  646. ,'R'
  647. ,createdDate
  648. FROM vwRemitTran rt WITH (NOLOCK)
  649. INNER JOIN dbo.vwTranReceivers tr WITH (NOLOCK) ON tr.tranId = rt.id
  650. WHERE tr.fullName = @receiverName
  651. AND tranStatus <> 'CANCEL'
  652. AND TR.mobile LIKE @receiverMobile
  653. AND createdDate BETWEEN DATEADD(DAY, - 1 * @maxDays, CAST(GETDATE() AS DATE))
  654. AND GETDATE()
  655. DECLARE @limitTxn INT
  656. ,@limTxnCount INT
  657. ,@type CHAR(1)
  658. ,@condition INT
  659. ,@isFirstTran CHAR(1)
  660. ,@countTxn INT
  661. WHILE EXISTS (
  662. SELECT TOP 1 1
  663. FROM #TBL_COMPLIANCE_NO_OF_TXN
  664. WHERE IS_CHECKED = 0
  665. )
  666. BEGIN
  667. SELECT @limitTxn = LIMIT_NO_OF_TXN
  668. ,@comRuleId = COMM_RULE_ID
  669. ,@ruleType = RULE_TYPE
  670. ,@periodInDays = PERIOD_DAYS
  671. ,@condition = condition
  672. ,@isDocRequired = IS_DOC_REQUIRED
  673. ,@rCountry = R_COUNNTRY
  674. FROM #TBL_COMPLIANCE_NO_OF_TXN
  675. WHERE IS_CHECKED = 0
  676. ORDER BY PERIOD_DAYS DESC
  677. IF (@condition = '11446')
  678. BEGIN
  679. IF NOT EXISTS (
  680. SELECT 1
  681. FROM (
  682. SELECT TOP 1 customerId
  683. FROM TRANSENDERS TS(NOLOCK)
  684. INNER JOIN remittran(NOLOCK) rt ON rt.id = ts.tranId
  685. WHERE TS.customerId = @customerId
  686. AND rt.tranStatus <> 'CANCEL'
  687. UNION ALL
  688. SELECT TOP 1 customerId
  689. FROM TRANSENDERSTEMP TT(NOLOCK)
  690. INNER JOIN remittrantemp(NOLOCK) rtt ON rtt.id = tt.tranId
  691. WHERE customerId = @customerId
  692. AND rtt.tranStatus <> 'CANCEL'
  693. ) a
  694. WHERE customerId = @customerId
  695. )
  696. BEGIN
  697. SELECT @countTxn = COUNT(*)
  698. FROM (
  699. SELECT TOP 1 customerId
  700. FROM TRANSENDERS TS(NOLOCK)
  701. INNER JOIN remittran(NOLOCK) rt ON rt.id = ts.tranId
  702. WHERE TS.customerId = @customerId
  703. AND rt.tranStatus <> 'CANCEL'
  704. UNION ALL
  705. SELECT TOP 1 customerId
  706. FROM TRANSENDERSTEMP TT(NOLOCK)
  707. INNER JOIN remittrantemp(NOLOCK) rtt ON rtt.id = tt.tranId
  708. WHERE customerId = @customerId
  709. AND rtt.tranStatus <> 'CANCEL'
  710. ) a
  711. WHERE customerId = @customerId
  712. BEGIN
  713. IF (@countTxn = 0)
  714. BEGIN
  715. SET @countTxn = 1
  716. END
  717. SET @isFirstTran = 'Y'
  718. IF (@isFirstTran = 'Y')
  719. BEGIN
  720. SET @message = 'The transaction is in <b style=''background-color:red; color:white;''>' + CASE
  721. WHEN @ruleType = 'B'
  722. THEN 'blocked'
  723. WHEN @ruleType = 'H'
  724. THEN 'HOLD'
  725. ELSE 'hold'
  726. END + '
  727. </b> because this is ' + (dbo.GetOrdinal(@countTxn)) + 'transaction'
  728. --+CASE WHEN @isFirstTran = 'Y' THEN '' ELSE 'receiver can receive' END +' maximum
  729. --(<b>'+CAST(@limitTxn AS VARCHAR)+' times</b>) only, in '+CAST(@periodInDays AS VARCHAR) + 'Days.'+ISNULL('Receiving country Limit: ' + @rCountryName, '')
  730. INSERT INTO #TBL_COMPLIANCE_RESULT
  731. SELECT CASE
  732. WHEN @ruleType = 'B'
  733. THEN 1
  734. WHEN @ruleType = 'H'
  735. THEN 2
  736. ELSE 3
  737. END
  738. ,@message
  739. ,@comRuleId
  740. ,CONCAT(dbo.GetOrdinal(@countTxn), ' Transaction') --CAST(@periodInDays AS VARCHAR) + ' days maximum number of txn exceeded',
  741. ,'RECEIVER'
  742. ,@isDocRequired
  743. END
  744. END
  745. END
  746. --11203 RECEIVER, 11202 SENDER
  747. IF @condition = 11312
  748. BEGIN
  749. IF @periodInDays <> 0
  750. SELECT @limTxnCount = COUNT(0)
  751. ,@type = 'R'
  752. FROM #tempNoOfTxn
  753. WHERE createdDate BETWEEN DATEADD(DAY, CASE
  754. WHEN @periodInDays = 1
  755. THEN 0
  756. ELSE - 1 * @periodInDays
  757. END, GETDATE())
  758. AND GETDATE()
  759. AND txnType = 'R'
  760. ELSE
  761. SET @limTxnCount = 0
  762. END
  763. ELSE IF @condition = 11311
  764. BEGIN
  765. IF @periodInDays <> 0
  766. SELECT @limTxnCount = COUNT(0)
  767. ,@type = 'S'
  768. FROM #tempNoOfTxn
  769. WHERE createdDate BETWEEN DATEADD(DAY, CASE
  770. WHEN @periodInDays = 1
  771. THEN 0
  772. ELSE - 1 * @periodInDays
  773. END, GETDATE())
  774. AND GETDATE()
  775. AND txnType = 'S'
  776. ELSE
  777. SET @limTxnCount = 0
  778. END
  779. IF (ISNULL(@limTxnCount, 0) + 1) > @limitTxn
  780. BEGIN
  781. SET @message = 'The transaction is in <b style=''background-color:red; color:white;''>' + CASE
  782. WHEN @ruleType = 'B'
  783. THEN 'blocked'
  784. WHEN @ruleType = 'Q'
  785. THEN 'questionnaire'
  786. ELSE 'hold'
  787. END + '
  788. </b> because ' + CASE
  789. WHEN @type = 'S'
  790. THEN 'sender can send'
  791. ELSE 'receiver can receive'
  792. END + ' maximum
  793. (<b>' + CAST(@limitTxn AS VARCHAR) + ' times</b>) only, in ' + CAST(@periodInDays AS VARCHAR) + 'Days.' + ISNULL('Receiving country Limit: ' + @rCountryName, '')
  794. INSERT INTO #TBL_COMPLIANCE_RESULT
  795. SELECT CASE
  796. WHEN @ruleType = 'B'
  797. THEN 1
  798. WHEN @ruleType = 'H'
  799. THEN 2
  800. ELSE 3
  801. END
  802. ,@message
  803. ,@comRuleId
  804. ,CAST(@periodInDays AS VARCHAR) + ' days maximum number of txn exceeded'
  805. ,'RECEIVER'
  806. ,@isDocRequired
  807. END
  808. UPDATE #TBL_COMPLIANCE_NO_OF_TXN
  809. SET IS_CHECKED = 1
  810. WHERE COMM_RULE_ID = @comRuleId
  811. END
  812. IF EXISTS (
  813. SELECT *
  814. FROM #TBL_COMPLIANCE_RESULT
  815. )
  816. BEGIN
  817. SELECT *
  818. FROM #TBL_COMPLIANCE_RESULT
  819. RETURN
  820. END
  821. --Return success message if there is no complaince matched txn
  822. SELECT ERROR_CODE = 0
  823. ,MSG = 'Success'
  824. ,RULE_ID = 0
  825. ,SHORT_MSG = 'Success'
  826. ,''
  827. ,0
  828. RETURN
  829. END
  830. END