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.

433 lines
30 KiB

1 year ago
  1. USE [FastMoneyPro_Remit]
  2. GO
  3. ALTER PROCEDURE [dbo].[proc_ExchangeRate]
  4. @User VARCHAR(100),
  5. @senderId BIGINT,
  6. @pCountryId INT,
  7. @deliveryMethodId INT,
  8. @pBankId BIGINT = NULL,
  9. @pBranchId BIGINT = NULL,
  10. @collCurr VARCHAR(3),
  11. @payoutCurr VARCHAR(3),
  12. @collAmt MONEY,
  13. @payoutAmt MONEY,
  14. @calBy CHAR(1),
  15. @tpExRate DECIMAL(30,12),
  16. @payOutPartnerId BIGINT,
  17. @paymentType VARCHAR(20),
  18. @processId VARCHAR(40)
  19. AS
  20. SET NOCOUNT ON;
  21. SET XACT_ABORT ON;
  22. BEGIN TRY
  23. DECLARE @complianceRuleId INT
  24. ,@cAmtUSD MONEY
  25. ,@complienceMessage VARCHAR(1000) = NULL
  26. ,@shortMsg VARCHAR(100) = NULL
  27. ,@complienceErrorCode TINYINT = NULL
  28. ,@compErrorCode INT
  29. ,@FOREX_SESSION_ID VARCHAR(40)
  30. ,@schemeId VARCHAR(10) = NULL
  31. ,@discountType VARCHAR(2) = null
  32. ,@discountvalue MONEY =NULL
  33. ,@couponType VARCHAR(3) = NULL
  34. ,@discountPercent MONEY = NULL
  35. ,@couponName VARCHAR(20) = NULL
  36. ,@customerType INT
  37. IF @paymentType IS NULL
  38. SET @paymentType = 'WALLET'
  39. DECLARE @sCurrCostRate FLOAT ,@sCurrHoMargin FLOAT ,@pCurrCostRate FLOAT ,@customerRate FLOAT ,@sAgentSettRate FLOAT,@exRate DECIMAL(12,9),@sCountryId INT
  40. DECLARE @iServiceCharge MONEY ,@iTAmt MONEY ,@iPAmt MONEY ,@iCAmt MONEY ,@iCustomerRate FLOAT
  41. DECLARE @place INT ,@currDecimal INT
  42. DECLARE @agentAvlLimit MONEY
  43. DECLARE @msg VARCHAR(MAX)
  44. DECLARE @sAgent BIGINT,@sAgentName VARCHAR(100),@sBranch INT,@sBranchName VARCHAR(100),@sSuperAgent INT,@sSuperAgentName VARCHAR(100)
  45. DECLARE @serviceCharge MONEY,@tAmt MONEY,@scDiscount MONEY = 0
  46. DECLARE @Status VARCHAR(10),@sBirthDate DATE,@sIdIssueDate DATE,@sIdExpiryDate DATE,@senderName VARCHAR(100),@sIdNo VARCHAR(50),@sIdType VARCHAR(50)
  47. ,@sMobile VARCHAR(15),@sOccupation VARCHAR(50)
  48. DECLARE @pBranch BIGINT,@pAgent BIGINT,@pSuperAgent BIGINT,@pAgentName VARCHAR(100),@receiverName VARCHAR(100)
  49. SELECT @sCountryId = 118,@sBranch = 2080
  50. SELECT @sAgent = sAgent, @sAgentName = sAgentName, @sBranch = sBranch, @sBranchName = sBranchName,
  51. @sSuperAgent = sSuperAgent, @sSuperAgentName = sSuperAgentName
  52. FROM dbo.FNAGetBranchFullDetails(@sBranch)
  53. ----SELECT @pCountry = COUNTRYNAME FROM COUNTRYMASTER (NOLOCK) WHERE COUNTRYID = @pCountryId
  54. SELECT TOP 1 @pAgent = AM.agentId
  55. FROM agentMaster AM(NOLOCK)
  56. WHERE AM.parentId = @payOutPartnerId AND agentType = 2903
  57. AND AM.isSettlingAgent = 'Y' AND AM.isApiPartner = 1
  58. IF EXISTS( SELECT TOP 1 'x'
  59. FROM dbo.TblPartnerwiseCountry(NOLOCK)
  60. WHERE IsActive = 1
  61. AND AgentId=@payOutPartnerId
  62. AND CountryId=@pCountryId
  63. AND PaymentMethod = @deliveryMethodId
  64. AND PartnerRate = 1)
  65. BEGIN
  66. IF ISNULL(@tpExRate,0) = 0
  67. BEGIN
  68. EXEC proc_errorHandler 5,'Fetch rate from partner side',NULL
  69. RETURN
  70. END
  71. END
  72. SELECT @pSuperAgent = sSuperAgent,@pAgent = sAgent,@pAgentName = sAgentName FROM dbo.FNAGetBranchFullDetails(@pAgent)
  73. BEGIN
  74. SELECT TOP 1
  75. @senderId = customerId ,
  76. @sIdNo = idNumber,
  77. @sIdType = idType,
  78. @agentAvlLimit = dbo.FNAGetCustomerACBal(email),
  79. @Status = CASE WHEN approvedDate IS NULL THEN 'pending' ELSE 'verified' END,
  80. @customerType = customerType
  81. FROM customerMaster WITH ( NOLOCK )
  82. WHERE email = @User AND approvedDate IS NOT NULL
  83. IF ISNULL(@Status,'pending') = 'pending'
  84. BEGIN
  85. EXEC proc_errorHandler 1,'Your account is not yet verified,Call:15886864 for verification.',NULL
  86. RETURN
  87. END
  88. IF @paymentType='autodebit'
  89. BEGIN
  90. DECLARE @DATE DATETIME, @NextDate datetime
  91. select @DATE = CAST(GETDATE() AS DATE)
  92. SELECT @NextDate = DATEADD(DAY,1,@DATE)
  93. SELECT @DATE = @DATE+' 23:20:00',@NextDate = @NextDate+' 00:40:00'
  94. IF GETDATE() BETWEEN @DATE AND @NextDate
  95. BEGIN
  96. SELECT '1' ErrorCode ,'KFTC service is not available between 11:30 PM to 12:30 AM' Msg ,NULL ID
  97. RETURN
  98. END
  99. END
  100. SELECT TOP 1 @sIdType = detailTitle FROM staticDataValue(NOLOCK) WHERE valueId = @sIdType
  101. SELECT TOP 1 @place = place ,
  102. @currDecimal = currDecimal
  103. FROM currencyPayoutRound(NOLOCK)
  104. WHERE ISNULL(isDeleted, 'N') = 'N'
  105. AND currency = @payoutCurr AND tranType IS NULL;
  106. SET @currDecimal = ISNULL(@currDecimal,0)
  107. IF @payoutCurr IS NULL
  108. BEGIN
  109. EXEC proc_errorHandler 1,'Currency not been defined yet for receiving country.',NULL
  110. RETURN;
  111. END;
  112. SELECT
  113. @sCurrCostRate = sCurrCostRate
  114. ,@sCurrHoMargin = sCurrHoMargin
  115. ,@sAgentSettRate = sAgentSettRate
  116. ,@customerRate = customerRate
  117. ,@pCurrCostRate = pCurrCostRate
  118. FROM dbo.FNAGetExRate(@sCountryId, @sAgent, @sBranch, @collCurr, @pCountryId, @pAgent, @payoutCurr, @deliveryMethodId)
  119. IF ISNULL(@sAgentSettRate, 0) = 0
  120. BEGIN
  121. SET @msg = 'Exchange rate not defined yet for sending currency (' + @payoutCurr + ')'
  122. EXEC proc_errorHandler 1,@msg,NULL
  123. RETURN
  124. END
  125. ----## FOR RIA AND CONTACT "LOG" GET ONE TIME RATE FROM PARTNER AND STORE IN TABLE ,"SYSTEM" IS FOR GME RATE,"PARTNER" GET RATE FROM PARTNER END REALTIME
  126. IF EXISTS(SELECT TOP 1 'X' FROM TblPartnerwiseCountry(NOLOCK) WHERE AgentId = @payOutPartnerId AND PaymentMethod = @deliveryMethodId AND IsActive = 1 AND GetRateFrom='Log')
  127. BEGIN
  128. SELECT TOP 1 @tpExRate = CurrCostRate FROM TBL_PARTNER_COST_RATE(NOLOCK)
  129. WHERE ProviderId = @payOutPartnerId AND GETDATE() BETWEEN EffectiveFrom AND EffectiveTo
  130. AND ToCurr = @payoutCurr AND FromCurr = 'USD' ORDER BY CreatedDate desc
  131. IF ISNULL(@tpExRate, 0) = 0
  132. BEGIN
  133. SET @msg = 'Exchange rate not defined yet for currency (' + @payoutCurr + ')'
  134. EXEC proc_errorHandler 5,@msg,NULL
  135. RETURN
  136. END
  137. END
  138. IF @tpExRate IS NOT NULL
  139. BEGIN
  140. SELECT @exRate = ROUND(ISNULL(@tpExRate,0)/@sAgentSettRate, 8),@pCurrCostRate = @tpExRate
  141. END
  142. ELSE
  143. SELECT @exRate = @customerRate
  144. IF @exRate IS NULL
  145. BEGIN
  146. SET @msg = 'Exchange rate not defined yet for sending currency (' + @payoutCurr + ')'
  147. EXEC proc_errorHandler 1,@msg,NULL
  148. RETURN
  149. END;
  150. ----- Calculation service charge using coupon
  151. -- IF EXISTS ( SELECT '1'
  152. -- FROM CouponIssue(NOLOCK) AS CI
  153. -- INNER JOIN CouponSetup(NOLOCK) AS CS
  154. -- ON CI.couponId = CS.rowId
  155. -- WHERE CI.customerId = @senderId
  156. -- AND CI.endDate >= GETDATE()
  157. -- AND CI.isActive = 'Y'
  158. -- AND CS.endDate >= GETDATE()
  159. -- AND CS.isActive = 'Y'
  160. -- AND CS.couponType = '1'
  161. -- AND CS.couponType = '1'
  162. -- AND (ISNULL(CS.usageLimit,0) = 0
  163. -- OR ISNULL(CS.usageLimit,0) > ISNULL(CI.usedCount,0))
  164. -- )
  165. --BEGIN
  166. SELECT TOP(1) @discountType = CS.discountType,
  167. @couponName = CS.couponName,
  168. @discountvalue = CS.discountValue,
  169. @schemeId = CI.rowId, -- ADD coponIssue ID
  170. @couponType = CS.couponType
  171. FROM CouponIssue(NOLOCK) CI
  172. INNER JOIN CouponSetup(NOLOCK) CS ON CI.couponId = CS.rowId
  173. AND CI.isActive = 'Y'
  174. AND CI.endDate >= GETDATE()
  175. AND CS.endDate >= GETDATE()
  176. AND CS.isActive = 'Y'
  177. AND CS.couponType = '1'
  178. AND customerId = @senderId
  179. AND CS.couponType = '1'
  180. AND (ISNULL(CS.usageLimit,0) = 0
  181. OR CS.usageLimit > CI.usedCount)
  182. ORDER BY CI.rowId ASC
  183. IF @discountType ='2'
  184. BEGIN
  185. SET @scDiscount = @discountvalue
  186. END
  187. --END
  188. IF @calBy = 'C'
  189. BEGIN
  190. SELECT @serviceCharge = amount
  191. FROM [dbo].FNAGetServiceCharge(@sCountryId,@sSuperAgent,@sAgent,@sBranch,
  192. @pCountryId,@pSuperAgent,@pAgent,@pBranch,@deliveryMethodId,@collAmt,@collCurr);
  193. IF @serviceCharge IS NULL
  194. BEGIN
  195. EXEC proc_errorHandler 1,'Service charge not defined yet for receiving country',NULL
  196. RETURN
  197. END
  198. IF @discountType = '1'
  199. BEGIN
  200. SET @discountPercent = @discountvalue
  201. SET @discountvalue = @serviceCharge * (@discountvalue/100)
  202. SET @scDiscount = @discountvalue
  203. END
  204. SET @tAmt = @collAmt - @serviceCharge;
  205. SET @payoutAmt = ( @collAmt - @serviceCharge ) * @exRate
  206. IF @payoutCurr = 'USD'
  207. SET @payoutAmt = ROUND(@payoutAmt,2)
  208. ELSE
  209. SET @payoutAmt = ROUND(@payoutAmt,0)
  210. END
  211. ELSE IF @calBy = 'P'
  212. BEGIN
  213. SET @tAmt = @payoutAmt / @exRate
  214. SELECT @serviceCharge = amount
  215. FROM [dbo].FNAGetServiceCharge(@sCountryId,@sSuperAgent,@sAgent,@sBranch,
  216. @pCountryId,@pSuperAgent,@pAgent,@pBranch,@deliveryMethodId,@tAmt, @collCurr);
  217. IF @serviceCharge IS NULL
  218. BEGIN
  219. EXEC proc_errorHandler 1,'Service charge not defined yet for receiving country',NULL
  220. RETURN
  221. END
  222. IF @discountType = '1'
  223. BEGIN
  224. SET @discountPercent = @discountvalue
  225. SET @discountvalue = @serviceCharge * (@discountvalue/100)
  226. SET @scDiscount = @discountvalue
  227. END
  228. SET @tAmt = ROUND(@tAmt, 2);
  229. SET @collAmt = ( @tAmt + @serviceCharge )
  230. SET @collAmt = ROUND(@collAmt, 0)
  231. END
  232. IF @serviceCharge > @collAmt
  233. BEGIN
  234. EXEC proc_errorHandler 1,'COLLECTION AMOUNT SHOULD BE MORE THAN SERVICE CHARGE',NULL
  235. RETURN
  236. END
  237. /* Easy Remit limit check */
  238. IF @customerType = '11048'
  239. BEGIN
  240. IF ISNULL(@collAmt, 0) > 1000000
  241. BEGIN
  242. EXEC proc_errorHandler 1,'You cannot remit more than one million(KRW)', NULL
  243. RETURN
  244. END
  245. END
  246. IF ISNULL(@paymentType,'wallet') = 'wallet'
  247. BEGIN
  248. IF ISNULL(@agentAvlLimit, 1) < ISNULL(@collAmt, 0)
  249. BEGIN
  250. EXEC proc_errorHandler 1,'You donot have sufficient balance to do the transaction',NULL
  251. RETURN;
  252. END
  253. END
  254. DECLARE @errorCode VARCHAR(5) ='0',@trantype VARCHAR(30)
  255. SET @trantype = CAST(@deliveryMethodId AS VARCHAR(30))
  256. --select flag = 's-limit', cAmt = @collAmt, pAmt = @payoutAmt, sCountryId = @sCountryId
  257. -- ,deliveryMethod = @trantype,pCountryId = @pCountryId,pCurr = @payoutCurr, collCurr = @collCurr
  258. -- ,pAgent = @pAgent, sAgent = @sAgent, sBranch = @sBranch
  259. --4. Validate Country Sending Limit
  260. EXEC PROC_CHECKCOUNTRYLIMIT @flag = 's-limit', @cAmt = @tAmt, @pAmt = @payoutAmt, @sCountryId = @sCountryId
  261. ,@deliveryMethod = @trantype,@pCountryId = @pCountryId,@pCurr = @payoutCurr, @collCurr = @collCurr
  262. ,@pAgent = @pAgent, @sAgent = @sAgent, @sBranch = @sBranch
  263. ,@msg = @msg OUT, @errorCode = @errorCode OUT
  264. IF @errorCode <> '0'
  265. BEGIN
  266. EXEC proc_errorHandler @errorCode,@msg,NULL
  267. RETURN
  268. END
  269. ----Validate Country Sending Limit END
  270. ----5. Validate Country Receiving Limit
  271. EXEC PROC_CHECKCOUNTRYLIMIT @flag = 'r-limit', @cAmt = @tAmt, @pAmt = @payoutAmt, @sCountryId = @sCountryId, @collMode = NULL
  272. ,@deliveryMethod = @deliveryMethodId,@sendingCustType = NULL,@pCountryId = @pCountryId,@pCurr = @payoutCurr, @collCurr = @collCurr
  273. ,@pAgent = @pAgent, @sAgent = @sAgent, @sBranch = @sBranch
  274. ,@msg = @msg OUT, @errorCode = @errorCode OUT
  275. IF @errorCode <> '0'
  276. BEGIN
  277. SELECT @errorCode ErrorCode, @msg Msg,null Id
  278. RETURN
  279. END
  280. ----Validate Country Receiving Limit
  281. SET @cAmtUSD = @tAmt / (@sCurrCostRate + ISNULL(@sCurrHoMargin, 0))
  282. EXEC [proc_complianceRuleDetail]
  283. @flag = 'sender-limit'
  284. ,@user = @user
  285. ,@sIdType = @sIdType
  286. ,@sIdNo = @sIdNo
  287. ,@receiverName = null
  288. ,@cAmt = @tAmt
  289. ,@cAmtUSD = @cAmtUSD
  290. ,@customerId = @senderId
  291. ,@pCountryId = @pCountryId
  292. ,@deliveryMethod= @deliveryMethodId
  293. ,@message = @complienceMessage OUTPUT
  294. ,@shortMessage = @shortMsg OUTPUT
  295. ,@errCode = @complienceErrorCode OUTPUT
  296. ,@ruleId = @complianceRuleId OUTPUT
  297. IF(@complienceErrorCode <> 0)
  298. BEGIN
  299. IF(@complienceErrorCode = 1)
  300. BEGIN
  301. SET @compErrorCode = 101
  302. END
  303. ELSE
  304. BEGIN
  305. SET @compErrorCode = 101
  306. INSERT remitTranComplianceTemp(csDetailTranId, matchTranId, agentRefId)
  307. SELECT @complianceRuleId, NULL, @processId
  308. --SELECT 102 errorCode,@msg msg, @complienceErrorCode id, @complienceMessage compApproveRemark,'compliance' vtype
  309. END
  310. INSERT INTO ComplianceLog(senderName, senderCountry, senderIdType, senderIdNumber, senderMobile, receiverName
  311. , receiverCountry,payOutAmt,complianceId,complianceReason,complainceDetailMessage,createdBy,createdDate,logType)
  312. SELECT @senderName, '118', @sIdType, @sIdNo, @sMobile, @receiverName
  313. , @pCountryId, @collAmt, @complianceRuleId, @shortMsg, @complienceMessage, @user, GETDATE(),'online'
  314. END
  315. ------------Validation End---------------------------------
  316. IF @complienceErrorCode = '1'
  317. BEGIN
  318. EXEC proc_errorHandler @compErrorCode,@shortMsg,@complienceErrorCode
  319. RETURN;
  320. END;
  321. SET @FOREX_SESSION_ID = NEWID()
  322. DECLARE @id BIGINT
  323. ----## lock ex rate for individual txn
  324. UPDATE exRateCalcHistory SET isExpired = 1 WHERE CUSTOMER_ID = @senderId AND isExpired = 0
  325. INSERT INTO exRateCalcHistory (
  326. CUSTOMER_ID,[USER_ID],FOREX_SESSION_ID,serviceCharge,pAmt,customerRate,sCurrCostRate,sCurrHoMargin
  327. ,sCurrAgentMargin,pCurrCostRate,pCurrHoMargin,pCurrAgentMargin,agentCrossSettRate,createdDate,isExpired,tAmt,schemeId
  328. )
  329. SELECT @senderId,@user,@FOREX_SESSION_ID,@serviceCharge,@payoutAmt,@exRate,@sCurrCostRate,@sCurrHoMargin
  330. ,0,@pCurrCostRate,0,0,@exRate,GETDATE(),0,@tAmt,@schemeId
  331. SET @id = @@IDENTITY
  332. SELECT ErrorCode = @errorCode ,
  333. Msg = 'Message' ,
  334. Id = @id,
  335. scCharge = @serviceCharge ,
  336. exRateDisplay = ROUND(@exRate , 6, -1),
  337. exRate = @exRate,
  338. pCurr = @payoutCurr ,
  339. collAmt = @collAmt ,
  340. pAmt = @payoutAmt ,
  341. sAmt = ROUND(@tAmt, 0) ,
  342. collCurr = @collCurr,
  343. scDiscount = @scDiscount ,
  344. tpExRate = @pCurrCostRate,
  345. EXRATEID = @FOREX_SESSION_ID,
  346. payOutPartnerId = @payOutPartnerId,
  347. schemeId = ISNULL(@schemeId,''),
  348. couponType = ISNULL(@couponType,''),
  349. discountType = ISNULL(@discountType,''),
  350. discountvalue = ISNULL(@scDiscount,''),
  351. discountPercent = ISNULL(@discountPercent,''),
  352. couponName = ISNULL(@couponName,'')
  353. END
  354. END TRY
  355. BEGIN CATCH
  356. IF @@TRANCOUNT<>0
  357. ROLLBACK TRANSACTION
  358. DECLARE @errorMessage VARCHAR(MAX)
  359. SET @errorMessage = ERROR_MESSAGE()
  360. EXEC proc_errorHandler 1, @errorMessage, @user
  361. END CATCH
  362. GO