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.

374 lines
9.5 KiB

1 year ago
  1. USE [FastMoneyPro_Remit]
  2. GO
  3. /****** Object: StoredProcedure [dbo].[proc_payTxnValidation] Script Date: 7/4/2019 11:35:48 AM ******/
  4. DROP PROCEDURE [dbo].[proc_payTxnValidation]
  5. GO
  6. /****** Object: StoredProcedure [dbo].[proc_payTxnValidation] Script Date: 7/4/2019 11:35:48 AM ******/
  7. SET ANSI_NULLS ON
  8. GO
  9. SET QUOTED_IDENTIFIER ON
  10. GO
  11. CREATE PROCEDURE [dbo].[proc_payTxnValidation](
  12. @flag VARCHAR(1)
  13. ,@user VARCHAR(50)
  14. ,@rowId BIGINT = NULL
  15. ,@controlNo VARCHAR(50) = NULL
  16. ,@partnerId VARCHAR(30) = NULL
  17. ,@pBranchId VARCHAR(50) = NULL
  18. )
  19. AS
  20. DECLARE
  21. @mapCodeDom VARCHAR(50)
  22. ,@tranStatus VARCHAR(50)
  23. ,@tranId INT
  24. ,@payStatus VARCHAR(50)
  25. ,@controlNoEncrypted VARCHAR(50)
  26. ,@agentType VARCHAR(50)
  27. ,@pTxnLocation VARCHAR(50)
  28. ,@pAgentLocation VARCHAR(50)
  29. ,@pAgent VARCHAR(50)
  30. ,@paymentMethod VARCHAR(50)
  31. ,@sBranchId VARCHAR(50)
  32. ,@branchName VARCHAR(200)
  33. ,@mapCodeInt VARCHAR(50)
  34. ,@lockStatus VARCHAR(50)
  35. ,@userAgentId INT
  36. ,@complianceHoldPay CHAR(1)
  37. SET @controlNo = UPPER(@controlNo)
  38. SET @controlNoEncrypted = DBO.FNAEncryptString(LTRIM(RTRIM(@controlNo))
  39. IF @flag = 'S'
  40. BEGIN
  41. IF (@partnerId='IME-D')
  42. BEGIN
  43. IF @user IS NULL
  44. BEGIN
  45. EXEC proc_errorHandler 1, 'Your session has expired. Please relogin to the system.', @controlNo
  46. RETURN
  47. END
  48. SELECT @userAgentId = agentId
  49. from applicationUsers with(nolock) where userName = @user
  50. IF @userAgentId <> 1001
  51. BEGIN
  52. DECLARE @hasRight CHAR(1), @payDomesticFunctionId VARCHAR(50)
  53. SET @payDomesticFunctionId = '40101311,40101520'
  54. SELECT @hasRight = dbo.FNAHasRight(@user, @payDomesticFunctionId)
  55. IF(@hasRight = 'N')
  56. BEGIN
  57. EXEC proc_errorHandler 1, 'You are not authorized to pay domestic transaction.', NULL
  58. RETURN
  59. END
  60. END
  61. DECLARE @settlingAgent INT
  62. IF EXISTS(SELECT 'A' FROM dbo.agentMaster WHERE agentId = @userAgentId AND agentType = 2903)
  63. BEGIN
  64. SET @settlingAgent = @userAgentId
  65. END
  66. ELSE
  67. BEGIN
  68. SELECT @settlingAgent = parentId FROM dbo.agentMaster WHERE agentId = @userAgentId
  69. END
  70. DECLARE @limitBal MONEY
  71. SET @limitBal = [dbo].FNAGetLimitBal(@settlingAgent)
  72. IF NOT EXISTS(SELECT 'A' FROM dbo.creditlimit (NOLOCK) WHERE agentId = @settlingAgent) AND ISNULL(@limitBal, 0) = 0
  73. BEGIN
  74. SELECT 1 errorCode,'Credit limit not set for receiving agent, please contact HO.' msg,NULL id,'creditLimit' vtype
  75. RETURN
  76. END
  77. IF @pBranchId IS NULL
  78. BEGIN
  79. EXEC proc_errorHandler 1, 'Please Choose Paying Agent', NULL
  80. RETURN
  81. END
  82. SELECT
  83. @mapCodeDom = mapCodeDom,
  84. @agentType = agentType,
  85. @pAgentLocation = agentLocation,
  86. @branchName = agentName
  87. FROM agentMaster WITH(NOLOCK) WHERE agentId = @pBranchId
  88. IF (@mapCodeDom IS NULL OR @mapCodeDom = '' OR @mapCodeDom = 0)
  89. BEGIN
  90. EXEC proc_errorHandler 1, 'Invalid Map Code', NULL
  91. RETURN
  92. END
  93. SELECT
  94. @tranStatus = tranStatus,
  95. @tranId = id,
  96. @payStatus = payStatus ,
  97. @controlNoEncrypted = rt.controlNo,
  98. @paymentMethod = paymentMethod,
  99. @sBranchId = sBranch,
  100. @pTxnLocation = pLocation,
  101. @complianceHoldPay = CASE WHEN ISNULL(tc.controlNo ,'')='' THEN 'N'
  102. ELSE 'Y'
  103. END
  104. FROM remitTran rt WITH(NOLOCK)
  105. LEFT JOIN tranPayCompliance tc WITH(NOLOCK)
  106. ON rt.controlNo = tc.controlNo
  107. WHERE rt.controlNo = @controlNoEncrypted
  108. IF @tranStatus IS NULL
  109. BEGIN
  110. EXEC proc_errorHandler 1000, 'Transaction not found', NULL
  111. RETURN
  112. END
  113. IF @agentType = 2903
  114. BEGIN
  115. SET @pAgent = @pBranchId
  116. END
  117. INSERT INTO tranViewHistory(
  118. controlNumber
  119. ,tranViewType
  120. ,agentId
  121. ,createdBy
  122. ,createdDate
  123. ,tranId
  124. )
  125. SELECT
  126. @controlNoEncrypted
  127. ,'PAY'
  128. ,@pBranchId
  129. ,@user
  130. ,GETDATE()
  131. ,@tranId
  132. IF @paymentMethod = 'Bank Deposit'
  133. BEGIN
  134. EXEC proc_errorHandler 1, 'Cannot process payment for Payment Type Bank Deposit', NULL
  135. RETURN
  136. END
  137. IF @sBranchId = @pBranchId
  138. BEGIN
  139. EXEC proc_errorHandler 1, 'Cannot process payment for same POS', @tranId
  140. RETURN
  141. END
  142. IF (@tranStatus = 'CancelRequest')
  143. BEGIN
  144. EXEC proc_errorHandler 1, 'Transaction has been requested for cancel', @controlNoEncrypted
  145. RETURN
  146. END
  147. IF (@tranStatus = 'Lock' )
  148. BEGIN
  149. EXEC proc_errorHandler 1, 'Transaction is locked', @controlNoEncrypted
  150. RETURN
  151. END
  152. IF (@tranStatus = 'Block')
  153. BEGIN
  154. EXEC proc_errorHandler 1, 'Transaction is blocked. Please Contact HO', @controlNoEncrypted
  155. RETURN
  156. END
  157. IF (@tranStatus = 'Paid')
  158. BEGIN
  159. EXEC proc_errorHandler 1, 'Transaction has already been paid', @controlNoEncrypted
  160. RETURN
  161. END
  162. IF (@payStatus = 'Paid')
  163. BEGIN
  164. EXEC proc_errorHandler 1, 'Transaction has already been paid', @controlNoEncrypted
  165. RETURN
  166. END
  167. IF (@tranStatus = 'Hold')
  168. BEGIN
  169. EXEC proc_errorHandler 1, 'Transaction is hold', @controlNoEncrypted
  170. RETURN
  171. END
  172. IF @tranStatus IN ('Hold','OFAC Hold','Compliance Hold','OFAC/Compliance Hold','Compliance Hold Pay')
  173. BEGIN
  174. EXEC proc_errorHandler 1, 'Transaction is hold', @controlNoEncrypted
  175. RETURN
  176. END
  177. IF (@tranStatus = 'Cancel')
  178. BEGIN
  179. EXEC proc_errorHandler 1, 'Transaction is cancelled', @controlNoEncrypted
  180. RETURN
  181. END
  182. IF (@tranStatus <> 'Payment')
  183. BEGIN
  184. EXEC proc_errorHandler 1, 'Transaction is not in authorized mode', @controlNoEncrypted
  185. RETURN
  186. END
  187. DECLARE @tranDistrictId INT, @payAgentDistrictId INT
  188. SELECT @payAgentDistrictId = districtId FROM apiLocationMapping WHERE apiDistrictCode = @pAgentLocation
  189. SELECT @tranDistrictId = districtId FROM apiLocationMapping WHERE apiDistrictCode = @pTxnLocation
  190. IF @payAgentDistrictId IS NULL
  191. BEGIN
  192. EXEC proc_errorHandler 1, 'Location not found. Please Contact HO', @controlNo
  193. RETURN
  194. END
  195. IF @tranDistrictId IS NULL
  196. BEGIN
  197. EXEC proc_errorHandler 1, 'Location not found. Please Contact HO', @controlNo
  198. RETURN
  199. END
  200. IF(@tranDistrictId <> @payAgentDistrictId)
  201. BEGIN
  202. EXEC proc_errorHandler 1, 'You are not allowed to pay this TXN. It is not within your district.', @controlNoEncrypted
  203. RETURN
  204. END
  205. IF @complianceHoldPay = 'Y'
  206. BEGIN
  207. EXEC proc_errorHandler 101, 'Transaction Verification Successful', @tranId
  208. END
  209. EXEC proc_errorHandler 0, 'Transaction Verification Successful', @tranId
  210. END
  211. IF (@partnerId='IME-I')
  212. BEGIN
  213. IF @pBranchId IS NULL
  214. BEGIN
  215. EXEC proc_errorHandler 1, 'Please Choose Agent', NULL
  216. RETURN
  217. END
  218. SELECT
  219. @mapCodeInt = mapCodeInt
  220. ,@agentType = agentType
  221. ,@pAgentLocation = agentLocation
  222. FROM agentMaster WITH(NOLOCK) WHERE agentId = @pBranchId
  223. IF (@mapCodeInt IS NULL OR @mapCodeInt = '' OR @mapCodeInt = 0)
  224. BEGIN
  225. EXEC proc_errorHandler 1, 'Invalid Map Code', NULL
  226. RETURN
  227. END
  228. SELECT
  229. @tranStatus = tranStatus
  230. , @tranId = id
  231. , @lockStatus = lockStatus
  232. , @payStatus = payStatus
  233. , @sBranchId = sBranch
  234. , @paymentMethod = paymentMethod
  235. , @complianceHoldPay = CASE WHEN ISNULL(tc.controlNo ,'')='' THEN 'N'
  236. ELSE 'Y'
  237. END
  238. FROM remitTran rt WITH(NOLOCK)
  239. LEFT JOIN tranPayCompliance tc WITH(NOLOCK)
  240. ON rt.controlNo = tc.controlNo
  241. WHERE rt.controlNo = @controlNoEncrypted
  242. IF @tranStatus IS NULL
  243. BEGIN
  244. EXEC proc_errorHandler 1000, 'Transaction not found', NULL
  245. RETURN
  246. END
  247. IF @agentType = 2903
  248. BEGIN
  249. SET @pAgent = @pBranchId
  250. END
  251. INSERT INTO tranViewHistory(
  252. controlNumber
  253. ,tranViewType
  254. ,agentId
  255. ,createdBy
  256. ,createdDate
  257. ,tranId
  258. )
  259. SELECT
  260. @controlNoEncrypted
  261. ,'PAY'
  262. ,@pBranchId
  263. ,@user
  264. ,GETDATE()
  265. ,@tranId
  266. IF @paymentMethod = 'Bank Deposit'
  267. BEGIN
  268. EXEC proc_errorHandler 1, 'Cannot process payment for Payment Type Bank Deposit', NULL
  269. RETURN
  270. END
  271. IF @sBranchId = @pBranchId
  272. BEGIN
  273. EXEC proc_errorHandler 1, 'Cannot process payment for same POS', @tranId
  274. RETURN
  275. END
  276. IF (@tranStatus = 'CancelRequest')
  277. BEGIN
  278. EXEC proc_errorHandler 1, 'Transaction has been requested for cancel', @controlNoEncrypted
  279. RETURN
  280. END
  281. IF (@lockStatus = 'Lock' )
  282. BEGIN
  283. EXEC proc_errorHandler 1, 'Transaction is locked', @controlNoEncrypted
  284. RETURN
  285. END
  286. IF (@tranStatus = 'Lock' )
  287. BEGIN
  288. EXEC proc_errorHandler 1, 'Transaction is locked', @controlNoEncrypted
  289. RETURN
  290. END
  291. IF (@tranStatus = 'Block')
  292. BEGIN
  293. EXEC proc_errorHandler 1, 'Transaction is blocked. Please Contact HO', @controlNoEncrypted
  294. RETURN
  295. END
  296. IF (@tranStatus = 'Paid')
  297. BEGIN
  298. EXEC proc_errorHandler 1, 'Transaction has already been paid', @controlNoEncrypted
  299. RETURN
  300. END
  301. IF (@payStatus = 'Paid')
  302. BEGIN
  303. EXEC proc_errorHandler 1, 'Transaction has already been paid', @controlNoEncrypted
  304. RETURN
  305. END
  306. IF (@tranStatus = 'Compliance')
  307. BEGIN
  308. EXEC proc_errorHandler 1, 'Transaction is in Compliance !!!', @controlNoEncrypted
  309. RETURN
  310. END
  311. IF (@tranStatus = 'Hold')
  312. BEGIN
  313. EXEC proc_errorHandler 1, 'Transaction is hold', @controlNoEncrypted
  314. RETURN
  315. END
  316. IF @tranStatus IN ('Hold','OFAC Hold','Compliance Hold','OFAC/Compliance Hold','Compliance Hold Pay')
  317. BEGIN
  318. EXEC proc_errorHandler 1, 'Transaction is hold', @controlNoEncrypted
  319. RETURN
  320. END
  321. IF (@tranStatus = 'Cancel')
  322. BEGIN
  323. EXEC proc_errorHandler 1, 'Transaction is cancelled', @controlNoEncrypted
  324. RETURN
  325. END
  326. IF (@tranStatus <> 'Payment')
  327. BEGIN
  328. EXEC proc_errorHandler 1, 'Transaction is not in authorized mode', @controlNoEncrypted
  329. RETURN
  330. END
  331. IF @complianceHoldPay = 'Y'
  332. BEGIN
  333. EXEC proc_errorHandler 101, 'Transaction Verification Successful', @tranId
  334. END
  335. EXEC proc_errorHandler 0, 'Transaction Verification Successful', @tranId
  336. END
  337. END
  338. GO