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.

331 lines
22 KiB

1 year ago
  1. USE [FastMoneyPro_Remit]
  2. GO
  3. /****** Object: StoredProcedure [dbo].[proc_complianceRuleDetail_Pay] Script Date: 9/27/2019 1:30:14 PM ******/
  4. SET ANSI_NULLS ON
  5. GO
  6. SET QUOTED_IDENTIFIER OFF
  7. GO
  8. CREATE proc [dbo].[proc_complianceRuleDetail_Pay]
  9. @user VARCHAR(50) = NULL
  10. ,@tranId BIGINT = NULL
  11. ,@tAmt MONEY = NULL
  12. ,@customerId INT = NULL
  13. ,@receiverId VARCHAR(50) = NULL
  14. ,@receiverMemId VARCHAR(30) = NULL
  15. ,@receiverName VARCHAR(200) = NULL
  16. ,@receiverMobile VARCHAR(50) = NULL
  17. ,@receiverAcNo VARCHAR(50) = NULL
  18. ,@masterId INT = NULL
  19. ,@paymentMethod INT = NULL
  20. ,@checkingFor CHAR(1) = NULL
  21. ,@result VARCHAR(MAX) = NULL OUTPUT
  22. ,@collMode VARCHAR(50) = NULL
  23. AS
  24. SET NOCOUNT ON
  25. SET XACT_ABORT ON
  26. /*
  27. 1> Get the data in temp table
  28. 2> Create the temp for condition
  29. 3> Dynamic query create for checking TRN TEMP Vs Condition Temp (Loop may required)
  30. 4> Data need to shift into main table so that each tran compain histry will be maintain
  31. 5>
  32. 6> Compose the message with matched criteria
  33. 7>
  34. */
  35. BEGIN
  36. DECLARE
  37. @rHub INT
  38. ,@rAgent INT
  39. ,@rZip INT
  40. ,@rCustType INT
  41. ,@rGroup INT
  42. SET @result = ''
  43. IF ISNULL(@masterId, 0) = 0 or ISNULL(@receiverId,'') = '' AND ISNULL(@receiverMobile,'') = ''
  44. RETURN
  45. CREATE TABLE #tempTran(id BIGINT PRIMARY KEY, rBranch INT, tAmt MONEY, rIdNumber VARCHAR(50),rMembershipId VARCHAR(50), receiverName VARCHAR(200), rMobile VARCHAR(50),
  46. approvedDate DATETIME, createdDate DATETIME, tranStatus VARCHAR(20), collMode VARCHAR(50),rAccountNo VARCHAR(50))
  47. DECLARE
  48. @amount MONEY
  49. ,@tranCount INT
  50. ,@period INT
  51. ,@nextAction CHAR(1)
  52. ,@txnAction CHAR(1)
  53. ,@denyTxn CHAR(1)
  54. --IF @tranId IS NOT NULL
  55. --BEGIN
  56. -- SELECT
  57. -- @receiverId = tr.idNumber
  58. -- ,@receiverMemId = membershipId
  59. -- ,@receiverName = trn.receiverName
  60. -- ,@receiverMobile = mobile
  61. -- ,@receiverAcNo = trn.accountNo
  62. -- FROM remitTran trn WITH(NOLOCK)
  63. -- INNER JOIN tranReceivers tr WITH(NOLOCK) ON trn.id = tr.tranId
  64. -- WHERE trn.id = @tranId
  65. --END
  66. DECLARE
  67. @sql VARCHAR(MAX)
  68. ,@sqlRec VARCHAR(MAX) = ''
  69. ,@sqlTrn VARCHAR(MAX) = ''
  70. CREATE TABLE #tempCriteria(rowId INT IDENTITY(1,1), criteria INT)
  71. INSERT #tempCriteria(criteria)
  72. SELECT DISTINCT criteria
  73. FROM csDetailRec cdr (NOLOCK)
  74. INNER JOIN csDetail cd (NOLOCK) ON cdr.csDetailId = cd.csDetailId
  75. WHERE cdr.csMasterId = @masterId
  76. AND (cdr.paymentMode = @paymentMethod OR cdr.paymentMode IS NULL)
  77. AND ISNULL(cdr.isEnable, 'N') = 'Y'
  78. AND ISNULL(cd.isEnable, 'N') = 'Y'
  79. --3. Construct String Query
  80. DECLARE @totalRows INT, @count INT, @criteria INT
  81. SET @count = 1
  82. SELECT @totalRows = COUNT(*) FROM #tempCriteria
  83. SET @sqlRec = ' AND ('
  84. WHILE(@count <= @totalRows)
  85. BEGIN
  86. SELECT @criteria = criteria FROM #tempCriteria WHERE rowId = @count
  87. IF((@criteria = 5003))
  88. SET @sqlRec = @sqlRec + ' idNumber2 = ''' + ISNULL(@receiverId, '-') + ''' OR'
  89. ELSE IF((@criteria = 5004) AND ISNULL(@receiverMemId, '') <> '')
  90. SET @sqlRec = @sqlRec + ' membershipId = ''' + ISNULL(@receiverMemId, '') + ''' OR'
  91. ELSE IF((@criteria = 5005) AND ISNULL(@receiverName, '') <> '')
  92. SET @sqlTrn = @sqlTrn + ' OR trn.receiverName = ''' + ISNULL(@receiverName, '') + ''''
  93. ELSE IF((@criteria = 5006) AND ISNULL(@receiverMobile, '') <> '')
  94. SET @sqlRec = @sqlRec + ' mobile = ''' + ISNULL(@receiverMobile, '') + ''' OR'
  95. ELSE IF((@criteria = 5007) AND ISNULL(@receiverAcNo, '') <> '')
  96. SET @sqlTrn = @sqlTrn + ' OR trn.accountNo = ''' + ISNULL(@receiverAcNo, '') + ''''
  97. --SET @sqlRec = @sqlRec + ' 1 = 1 OR'
  98. SET @count = @count + 1
  99. END
  100. --DECLARE @complianceHoldCriteria VARCHAR(MAX)
  101. --SET @complianceHoldCriteria=' AND (t.rMobile = ''' + ISNULL(@receiverMobile, '') + ''' OR t.rIdNumber =''' + ISNULL(@receiverId, '') + ''')'
  102. SET @sqlRec = LEFT(@sqlRec, LEN(@sqlRec) - 2) + ')'
  103. DECLARE @cutOffDate VARCHAR(10) = CONVERT(VARCHAR, DATEADD(Day,-45, GETDATE()), 101)
  104. SET @sql = '
  105. SELECT
  106. trn.id
  107. ,trn.pBranch
  108. ,trn.tAmt
  109. ,T.rIdNumber
  110. ,T.rMembershipId
  111. ,trn.receiverName
  112. ,T.rMobile
  113. ,trn.approvedDate
  114. ,trn.createdDate
  115. ,trn.tranStatus
  116. ,trn.collMode
  117. ,trn.accountNo
  118. FROM vwRemitTran trn WITH(NOLOCK)
  119. INNER JOIN
  120. (
  121. SELECT
  122. tranId
  123. ,rIdNumber = idNumber2
  124. ,rMobile = mobile
  125. ,rMembershipId = membershipId
  126. FROM vwTranReceivers WITH(NOLOCK)
  127. WHERE 1=1 '
  128. + @sqlRec +
  129. '
  130. )T ON trn.id = T.tranId
  131. WHERE tranStatus NOT LIKE ''%Cancel%''
  132. AND ControlNo Not Like ''OIII%''
  133. AND ISNULL(approvedDate, createdDate) > ''' + @cutOffDate + ''' ' +
  134. @sqlTrn + '
  135. '
  136. PRINT @sql
  137. INSERT INTO #tempTran
  138. EXEC (@sql)
  139. SET @sql = ''
  140. IF @checkingFor = 'v'
  141. BEGIN
  142. DECLARE @rBranch INT
  143. SELECT @rBranch = agentId FROM applicationUsers WITH(NOLOCK) WHERE userName = @user
  144. INSERT INTO #tempTran(id, rBranch, tAmt, rIdNumber, receiverName, rMobile, createdDate, tranStatus, collMode,rAccountNo)
  145. SELECT 0, @rBranch, @tAmt, @receiverId, @receiverName, @receiverMobile, dbo.FNADateFormatTZ(GETDATE(), @user), 'Payment', @collMode,@receiverAcNo
  146. END
  147. --SELECT * FROM #tempTran
  148. DECLARE @today DATETIME = CAST(CONVERT(VARCHAR,GETDATE(),101) AS DATETIME)
  149. CREATE TABLE #tempQuery(rowId INT IDENTITY(1,1), csDetailRecId INT, query VARCHAR(MAX))
  150. INSERT #tempQuery(csDetailRecId, query)
  151. SELECT
  152. csDetailRecId
  153. ,query = 'SELECT ' + CAST(csDetailRecId AS VARCHAR)+ ', '+
  154. CASE
  155. WHEN checkType = 'SUM' THEN '(ISNULL(SUM(tAmt), 0) + ' + CAST(@tAmt AS VARCHAR) + ') '
  156. WHEN checkType = 'COUNT' THEN
  157. CASE
  158. WHEN ISNULL(condition,4600) = 4600 THEN ' COUNT(trn.id)' --4600 - Aggregate Rule
  159. WHEN condition = 4601 THEN ' COUNT(DISTINCT trn.rBranch)' --4601 - Multiple POS
  160. --WHEN condition = 4602 THEN ' COUNT(DISTINCT trn.sIdNumber)' --4602 - Multiple Beneficiary(Same Sender)
  161. WHEN condition = 4603 THEN ' COUNT(DISTINCT trn.rIdNumber)' --4603 - Multiple Sender(Same Beneficiary)
  162. END
  163. END
  164. +
  165. ' FROM #tempTran trn WITH(NOLOCK)
  166. WHERE ISNULL(approvedDate, createdDate) BETWEEN
  167. '''
  168. +
  169. CASE WHEN ISNULL(period,0) = 0 THEN '1900-01-01' ELSE CONVERT(VARCHAR, DATEADD(D, -(period-1), @today), 101) END
  170. + ''' AND '''
  171. + CASE WHEN ISNULL(period,0) = 0 THEN '2100-12-31' ELSE CONVERT(VARCHAR, GETDATE(), 101) + ' 23:59:59:998' END
  172. + ''''
  173. +
  174. CASE WHEN collModeDesc IS NOT NULL THEN ' AND trn.collMode = ''' + collModeDesc + '''' ELSE '' END
  175. +
  176. CASE
  177. WHEN criteria = 5003 THEN ' AND trn.rIdNumber = ''' + ISNULL(@receiverId, '') + ''' GROUP BY trn.rIdNumber'
  178. WHEN criteria = 5004 THEN ' AND trn.rMembershipId = ''' + ISNULL(@receiverMemId, '') + ''' GROUP BY trn.rMembershipId'
  179. WHEN criteria = 5005 THEN ' AND trn.receiverName = ''' + ISNULL(@receiverName, '') + ''' GROUP BY trn.receiverName'
  180. WHEN criteria = 5006 THEN ' AND trn.rMobile = ''' + ISNULL(@receiverMobile, '') + ''' GROUP BY trn.rMobile'
  181. WHEN criteria = 5007 THEN ' AND trn.rAccountNo = ''' + ISNULL(@receiverAcNo, '') + ''' GROUP BY trn.rAccountNo'
  182. END
  183. +
  184. CASE WHEN ISNULL(parameter,0) > 0 THEN
  185. +
  186. ' HAVING '
  187. +
  188. CASE
  189. WHEN checkType = 'SUM' THEN
  190. '(ISNULL(SUM(tAmt), 0)) '
  191. WHEN checkType = 'COUNT' THEN
  192. CASE
  193. WHEN ISNULL(condition,4600) = 4600 THEN ' COUNT(trn.id)'
  194. WHEN condition = 4601 THEN ' COUNT(DISTINCT trn.rBranch)'
  195. --WHEN condition = 4602 THEN ' COUNT(DISTINCT trn.sIdNumber)'
  196. WHEN condition = 4603 THEN ' COUNT(DISTINCT trn.rIdNumber)'
  197. END
  198. END
  199. +
  200. '>='
  201. +
  202. CAST(parameter AS VARCHAR)
  203. ELSE ''
  204. END
  205. +
  206. ' UNION ALL'
  207. FROM
  208. (
  209. SELECT
  210. csDetailRecId
  211. ,cdr.csMasterId
  212. ,cdr.condition
  213. ,cdr.collMode
  214. ,collModeDesc = sdv.detailTitle
  215. ,cdr.paymentMode
  216. ,checkType
  217. ,parameter
  218. ,cdr.period
  219. ,criteria
  220. FROM csDetailRec cdr WITH(NOLOCK)
  221. INNER JOIN csDetail cd (NOLOCK) ON cdr.csDetailId = cd.csDetailId
  222. LEFT JOIN dbo.staticDataValue sdv WITH(NOLOCK) ON cdr.collMode = sdv.valueId
  223. WHERE cdr.csMasterId = @masterId
  224. AND (cdr.paymentMode = @paymentMethod OR cdr.paymentMode IS NULL)
  225. AND ISNULL(cdr.isEnable, 'N') = 'Y'
  226. AND ISNULL(cd.isEnable, 'N') = 'Y'
  227. ) X
  228. SELECT @totalRows = COUNT(*) FROM #tempQuery
  229. UPDATE #tempQuery
  230. SET query = LEFT(query, LEN(query) - 9)
  231. WHERE rowId = @totalRows
  232. SELECT @sql = COALESCE(@sql + ' ', '') + query FROM #tempQuery
  233. PRINT @sql
  234. --End of Contruct string Query--------------------------------------------------------------------------------------------------
  235. --4. String Query Execution-----------------------------------------------------------------------------------------------------
  236. CREATE TABLE #tempResult(rowId INT IDENTITY(1,1), csDetailRecId INT, parameter INT, matchTranId VARCHAR(MAX))
  237. INSERT #tempResult(csDetailRecId, parameter)
  238. EXEC (@sql)
  239. --------------------------------------------------------------------------------------------------------------------------------
  240. --5. Select compliance Detail ID and Matched TXN Id and insert into remitTranCompliance Table------------------------------------
  241. DELETE FROM #tempTran WHERE ISNULL(id, 0) = 0
  242. IF EXISTS(SELECT 'X' FROM #tempResult)
  243. BEGIN
  244. DECLARE @csDetailRecId INT, @tranIds VARCHAR(MAX)
  245. SELECT @totalRows = COUNT(*) FROM #tempResult
  246. --SELECT * from #tempResult -- test query
  247. --select * from #tempTran --test query
  248. SET @count = 1
  249. WHILE(@count <= @totalRows)
  250. BEGIN
  251. SELECT @csDetailRecId = csDetailRecId FROM #tempResult WHERE rowId = @count
  252. SELECT @period = period, @nextAction = nextAction FROM csDetailRec WITH(NOLOCK) WHERE csDetailRecId = @csDetailRecId
  253. SELECT @tranIds = COALESCE(ISNULL(@tranIds + ',', ''), '') + CAST(id AS VARCHAR) FROM #tempTran WHERE
  254. ISNULL(approvedDate, createdDate) BETWEEN CONVERT(VARCHAR, DATEADD(D, -(@period-1), @today), 101)
  255. AND CONVERT(VARCHAR, GETDATE(), 101) + ' 23:59:59:998'
  256. IF ISNULL(@nextAction, 'H') = 'M' AND ISNULL(@txnAction, '') <> 'B' AND ISNULL(@txnAction, '') <> 'C'
  257. SET @txnAction = 'M'
  258. IF ISNULL(@nextAction, 'H') = 'H' AND ISNULL(@txnAction, '') <> 'B'
  259. SET @txnAction = 'C'
  260. IF ISNULL(@nextAction, 'H') = 'B'
  261. SET @txnAction = 'C'--'B' -- No need to block txn in pay side
  262. IF @checkingFor = 'i'
  263. BEGIN
  264. INSERT remitTranCompliancePay(tranId, csDetailTranId, matchTranId)
  265. SELECT @tranId, @csDetailRecId, @tranIds
  266. END
  267. ELSE IF @checkingFor = 'v'
  268. BEGIN
  269. INSERT remitTranCompliancePayTemp(csDetailTranId, matchTranId, tranId)
  270. SELECT @csDetailRecId, @tranIds, @tranId
  271. END
  272. SET @tranIds = NULL
  273. SET @count = @count + 1
  274. END
  275. SET @result = @txnAction
  276. END
  277. END
  278. GO