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.

273 lines
18 KiB

1 year ago
  1. USE [FastMoneyPro_Remit]
  2. GO
  3. /****** Object: StoredProcedure [dbo].[proc_PayAcDepositV2] Script Date: 9/27/2019 1:30:14 PM ******/
  4. SET ANSI_NULLS ON
  5. GO
  6. SET QUOTED_IDENTIFIER ON
  7. GO
  8. CREATE proc [dbo].[proc_PayAcDepositV2]
  9. @flag VARCHAR(50)
  10. ,@pAgent INT = NULL
  11. ,@mapCodeInt VARCHAR(100) = NULL
  12. ,@tranIds VARCHAR(MAX) = NULL
  13. ,@fromDate VARCHAR(20) = NULL
  14. ,@toDate VARCHAR(20) = NULL
  15. ,@user VARCHAR(50) = NULL
  16. AS
  17. SET NOCOUNT ON;
  18. SET XACT_ABORT ON;
  19. DECLARE @pAgentName varchar(200)
  20. ,@pBranch int
  21. ,@pBranchName varchar(200)
  22. ,@pState varchar(200)
  23. ,@pDistrict varchar(200)
  24. ,@pLocation varchar(50)
  25. ,@tranNos VARCHAR(MAX)
  26. ,@sql VARCHAR(MAX)
  27. /*
  28. Exec proc_PayAcDepositV2 @flag='pendingList',@user='admin'
  29. Exec proc_PayAcDepositV2 @flag='pendingListDom',@mapCodeInt = '11300000',@user='dipesh'
  30. EXEC proc_domesticUnpaidListApi @flag = 'domList', @user = 'dipesh', @bankId = '11300000'
  31. */
  32. IF @flag = 'pendingList'
  33. BEGIN
  34. SET @sql =
  35. 'SELECT
  36. pAgent = pAgent
  37. ,pAgentName = pAgentName
  38. ,txnCount = COUNT(*)
  39. ,amt = SUM(pAmt)
  40. FROM remitTran rt WITH(NOLOCK)
  41. WHERE 1=1'
  42. IF @fromDate IS NOT NULL AND @toDate IS NOT NULL
  43. SET @sql = @sql +' AND rt.createdDate between '''+@fromDate+''' and '''+@toDate+' 23:59:59'''
  44. SET @sql = @sql +'
  45. AND paymentMethod in (''Bank Deposit'' ,''Relief Fund'')
  46. AND tranStatus = ''Payment''
  47. AND payStatus = ''Unpaid''
  48. AND tranType = ''I''
  49. GROUP BY pAgent, pAgentName'
  50. EXEC(@sql)
  51. SET @sql= 'SELECT
  52. pAgent = pBank
  53. ,pAgentName = pBankName
  54. ,txnCount = COUNT(*)
  55. ,amt = SUM(pAmt)
  56. FROM remitTran rt WITH(NOLOCK)
  57. WHERE 1=1'
  58. IF @fromDate IS NOT NULL AND @toDate IS NOT NULL
  59. SET @sql = @sql +' AND rt.createdDate between '''+@fromDate+''' and '''+@toDate+' 23:59:59'''
  60. SET @sql = @sql +'
  61. AND paymentMethod = ''Bank Deposit''
  62. AND tranStatus = ''Payment''
  63. AND payStatus = ''Unpaid''
  64. AND tranType = ''D''
  65. GROUP BY pBank, pBankName'
  66. EXEC(@sql)
  67. RETURN
  68. END
  69. IF @flag = 'pendingListIntl'
  70. BEGIN
  71. SET @sql =
  72. 'SELECT
  73. [Control No] = dbo.FNADecryptString(rt.controlNo)
  74. ,[Tran No] = rt.id
  75. ,[Sending Country] = rt.sCountry
  76. ,[Sending Agent] = rt.sAgentName
  77. ,[Bank Name] = rt.pBankName
  78. ,[Branch Name] = rt.pBankBranchName
  79. ,[Receiver Name] = rec.firstName + ISNULL( '' '' + rec.middleName, '''') + ISNULL( '' '' + rec.lastName1, '''') + ISNULL( '' '' + rec.lastName2, '''')
  80. ,[Bank A/C No] = rt.accountNo
  81. ,[Confirm Date] = rt.approvedDate
  82. ,[Payout Amount] = rt.pAmt
  83. ,[Unpaid Days] = DATEDIFF(D,rt.approvedDate,GETDATE())
  84. FROM [dbo].remitTran rt WITH(NOLOCK)
  85. inner join tranReceivers rec with(nolock) on rt.id = rec.tranId
  86. WHERE 1=1'
  87. IF @fromDate IS NOT NULL AND @toDate IS NOT NULL
  88. SET @sql = @sql +' AND rt.createdDate between '''+@fromDate+''' and '''+@toDate+' 23:59:59'''
  89. SET @sql = @sql +'
  90. AND pAgent = '''+CAST(@pAgent AS VARCHAR)+'''
  91. AND tranStatus = ''Payment''
  92. AND paymentMethod IN (''Bank Deposit'' ,''Relief Fund'')
  93. AND payStatus = ''Unpaid''
  94. AND rt.sCountry <> ''Nepal''
  95. AND rt.tranType = ''I''
  96. ORDER BY [Unpaid Days] DESC'
  97. EXEC(@sql)
  98. RETURN
  99. END
  100. IF @flag = 'pendingListDom'
  101. BEGIN
  102. SET @sql =
  103. 'SELECT
  104. [Control No] = dbo.FNADecryptString(rt.controlNo)
  105. ,[Tran No] = rt.id
  106. ,[Sending Agent] = rt.sAgentName
  107. ,[Bank Name] = rt.pBankName
  108. ,[Branch Name] = rt.pBankBranchName
  109. ,[Receiver Name] = rec.firstName + ISNULL( '' '' + rec.middleName, '''') + ISNULL( '' '' + rec.lastName1, '''') + ISNULL( '' '' + rec.lastName2, '''')
  110. ,[Bank A/C No] = rt.accountNo
  111. ,[Confirm Date] = rt.approvedDate
  112. ,[Payout Amount] = rt.pAmt
  113. ,[Unpaid Days] = DATEDIFF(D,rt.approvedDate,GETDATE())
  114. FROM [dbo].remitTran rt WITH(NOLOCK)
  115. inner join tranReceivers rec with(nolock) on rt.id = rec.tranId
  116. WHERE 1=1'
  117. IF @fromDate IS NOT NULL AND @toDate IS NOT NULL
  118. SET @sql = @sql +' AND rt.createdDate between '''+@fromDate+''' and '''+@toDate+' 23:59:59'''
  119. SET @sql = @sql +'
  120. AND pBank = '''+CAST(@pAgent AS VARCHAR)+'''
  121. AND tranStatus = ''Payment''
  122. AND paymentMethod = ''Bank Deposit''
  123. AND payStatus = ''Unpaid''
  124. AND rt.sCountry = ''Nepal''
  125. AND tranType = ''D''
  126. ORDER BY [Unpaid Days] DESC'
  127. EXEC(@sql)
  128. RETURN
  129. END
  130. IF @flag = 'payIntl'
  131. BEGIN
  132. DECLARE @tranDetail TABLE(id INT IDENTITY(1,1), tranId VARCHAR(50), controlNo VARCHAR(50), sRouteId VARCHAR(5))
  133. SET @sql = 'SELECT id, controlNo, sRouteId FROM dbo.remitTran WITH(NOLOCK) WHERE id IN (' + @tranIds + ') AND tranStatus = ''Payment'' AND payStatus = ''Unpaid'''
  134. INSERT INTO @tranDetail
  135. EXEC (@sql)
  136. IF NOT EXISTS(SELECT 'X' FROM @tranDetail)
  137. BEGIN
  138. EXEC proc_errorHandler 1, 'No Transaction Found.', NULL
  139. RETURN
  140. END
  141. SELECT
  142. @pAgent = am.agentId
  143. ,@pAgentName = am.agentName
  144. ,@pBranch = bm.agentId
  145. ,@pBranchName = bm.agentName
  146. ,@pState = bm.agentState
  147. ,@pDistrict = bm.agentDistrict
  148. ,@pLocation = bm.agentLocation
  149. FROM agentMaster am WITH(NOLOCK)
  150. LEFT JOIN agentMaster bm WITH(NOLOCK) ON am.agentId = bm.parentId AND bm.isHeadOffice = 'Y'
  151. WHERE am.agentId = @pAgent and isnull(bm.isDeleted,'N') = 'N' and bm.isActive = 'Y'
  152. IF @pBranch IS NULL
  153. BEGIN
  154. SELECT TOP 1
  155. @pAgent = am.agentId
  156. ,@pAgentName = am.agentName
  157. ,@pBranch = bm.agentId
  158. ,@pBranchName = bm.agentName
  159. ,@pState = bm.agentState
  160. ,@pDistrict = bm.agentDistrict
  161. ,@pLocation = bm.agentLocation
  162. FROM agentMaster am WITH(NOLOCK)
  163. LEFT JOIN agentMaster bm WITH(NOLOCK) ON am.agentId = bm.parentId
  164. WHERE am.agentId = @pAgent and isnull(bm.isDeleted,'N') = 'N' and bm.isActive = 'Y'
  165. END
  166. BEGIN TRAN
  167. UPDATE remitTran SET
  168. pBranch = @pBranch
  169. ,pBranchName = @pBranchName
  170. ,pState = @pState
  171. ,pDistrict = @pDistrict
  172. ,pAgentComm = case when rt.paymentMethod='Relief Fund' then 0 else (
  173. SELECT amount FROM dbo.FNAGetPayComm(
  174. NULL
  175. ,(SELECT countryId FROM countryMaster WITH(NOLOCK) WHERE countryName = rt.sCountry), NULL, 1002, 151, @pLocation, @pBranch, 'NPR'
  176. ,2, rt.cAmt, rt.pAmt, rt.serviceCharge, NULL, NULL
  177. )
  178. )
  179. end
  180. ,pAgentCommCurrency = 'NPR'
  181. ,pSuperAgentComm = 0
  182. ,pSuperAgentCommCurrency = 'NPR'
  183. ,tranStatus = 'Paid'
  184. ,payStatus = 'Paid'
  185. ,paidBy = @user
  186. ,paidDate = dbo.FNAGetDateInNepalTZ()
  187. ,paidDateLocal = GETDATE()
  188. FROM remitTran rt WITH(NOLOCK)
  189. INNER JOIN @tranDetail td on rt.id = td.tranId
  190. -- ## Update Accounting
  191. EXEC dbo.proc_payAcDepositAC
  192. @flag = 'payIntl'
  193. ,@user = @user
  194. ,@tranIds = @tranIds
  195. -- ## sending sms
  196. insert into smsQueueAcDepositTxn(tranId)
  197. select tranId from @tranDetail
  198. -- ## Queue Table for Data Integration
  199. INSERT INTO payQueue2(controlNo, pAgent, pAgentName, pBranch, pBranchName, paidBy, paidDate, paidBenIdType, paidBenIdNumber, routeId)
  200. SELECT controlNo, @pAgent, @pAgentName, @pBranch, @pBranchName, @user, dbo.FNAGetDateInNepalTZ(), NULL, NULL, sRouteId
  201. FROM @tranDetail WHERE sRouteId IS NOT NULL
  202. COMMIT TRAN
  203. EXEC proc_errorHandler 0, 'Transaction(s) paid successfully', NULL
  204. RETURN
  205. END
  206. IF @flag = 'payDom'
  207. BEGIN
  208. DECLARE @tranDomDetail TABLE(id INT IDENTITY(1,1),tranId VARCHAR(50),controlNo VARCHAR(50), controlNoEncInficare VARCHAR(20))
  209. DECLARE @sqlDom VARCHAR(MAX)
  210. SET @sqlDom = 'SELECT id, controlNo, controlNoEncInficare = dbo.encryptDbLocal(dbo.FNADecryptString(controlNo)) FROM dbo.remitTran WITH(NOLOCK) WHERE id IN (' + @tranIds + ') AND tranStatus = ''Payment'' AND payStatus = ''Unpaid'''
  211. INSERT INTO @tranDomDetail
  212. EXEC (@sqlDom)
  213. IF NOT EXISTS(SELECT 'X' FROM @tranDomDetail)
  214. BEGIN
  215. EXEC proc_errorHandler 1, 'No Transaction Found.', NULL
  216. RETURN
  217. END
  218. BEGIN TRAN
  219. UPDATE remitTran SET
  220. tranStatus = 'Paid'
  221. ,payStatus = 'Paid'
  222. ,pAgent = pBank
  223. ,pAgentName = pBankName
  224. ,pBranch = pBankBranch
  225. ,pBranchName = pBankBranchName
  226. ,pSuperAgentComm = 0
  227. ,pSuperAgentCommCurrency = 'NPR'
  228. ,pAgentComm = 0
  229. ,pAgentCommCurrency = 'NPR'
  230. ,paidBy = @user
  231. ,paidDate = dbo.FNAGetDateInNepalTZ()
  232. ,paidDateLocal = GETDATE()
  233. FROM remitTran rt WITH(NOLOCK)
  234. INNER JOIN @tranDomDetail td ON rt.id = td.tranId
  235. -- ## Update Accounting
  236. EXEC dbo.proc_payAcDepositAC
  237. @flag = 'payDom'
  238. ,@user = @user
  239. ,@tranIds = @tranIds
  240. COMMIT TRAN
  241. EXEC proc_errorHandler 0, 'Transaction(s) paid successfully', NULL
  242. END
  243. GO