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.

289 lines
22 KiB

  1. USE [FastMoneyPro_Remit]
  2. GO
  3. /****** Object: StoredProcedure [dbo].[proc_InsertRewardPoints] Script Date: 1/16/2024 3:38:46 PM ******/
  4. SET ANSI_NULLS ON
  5. GO
  6. SET QUOTED_IDENTIFIER ON
  7. GO
  8. ALTER PROC [dbo].[proc_InsertRewardPoints] (
  9. @Flag VARCHAR(20)
  10. ,@TranId BIGINT = NULL
  11. ,@CustomerId BIGINT = NULL
  12. ,@ReferralId BIGINT = NULL
  13. ,@rewardPoints INT = NULL
  14. ,@rewardValue MONEY = NULL
  15. ,@type VARCHAR(200) = NULL
  16. ,@pageSize VARCHAR(50) = NULL
  17. ,@pageNumber VARCHAR(50) = NULL
  18. ,@sortBy VARCHAR(50) = NULL
  19. ,@sortOrder VARCHAR(50) = NULL
  20. ,@newPoints INT = NULL
  21. ,@oldPoints INT = NULL
  22. ,@promotionType VARCHAR(50) = NULL
  23. ,@user VARCHAR(50) = NULL
  24. ,@isActive BIT = NULL
  25. ,@rowId INT = NULL
  26. )
  27. AS
  28. ;
  29. SET NOCOUNT ON;
  30. SET XACT_ABORT ON;
  31. DECLARE @table VARCHAR(MAX)
  32. ,@select_field_list VARCHAR(MAX)
  33. ,@extra_field_list VARCHAR(MAX)
  34. ,@sql_filter VARCHAR(MAX)
  35. ,@ACC_NUM VARCHAR(30)
  36. -- #1526 - Post production fixes for Redeem & Earn
  37. BEGIN
  38. DECLARE @sourceCustomerId INT, @destinationCustomerId INT, @code NVARCHAR(50), @runningBalance MONEY, @totalDrAmount MONEY
  39. , @totalCrAmount MONEY , @transactionPoints INT, @registrationPoints INT, @EquivalentPointsForOne INT, @AvailableBalance MONEY
  40. SELECT @registrationPoints = Points
  41. FROM TBL_PROMOTION_SETUP (NOLOCK)
  42. WHERE PromotionType = 'REGISTRATION'
  43. AND IsActive = 1
  44. SELECT @transactionPoints = Points
  45. FROM TBL_PROMOTION_SETUP (NOLOCK)
  46. WHERE PromotionType = 'TRANSACTION'
  47. AND IsActive = 1
  48. SELECT @EquivalentPointsForOne = Points
  49. FROM TBL_PROMOTION_MASTER_SETUP (NOLOCK)
  50. WHERE IsActive = 1
  51. IF @Flag = 'REGISTER'
  52. BEGIN
  53. --@CustomerId = Customer who is newly registering in the system
  54. --@ReferralId = Customer who is already in the system/ who have referred @CustomerId
  55. --EXEC proc_InsertRewardPoints @Flag = 'REGISTER', @CustomerId = 1, @ReferralId = 2
  56. INSERT INTO Customer_Promotion(sourceCustomerId, destinationCustomerId, code, codeType, referenceId, rewardType, amount, createdDate, status, approvedDate, tranType, runningBalance, EquivalentPoints)
  57. SELECT @ReferralId,@CustomerId, membershipId, 'REGISTRATION', @ReferralId, 'REFER_EARN', @registrationPoints/@EquivalentPointsForOne, GETDATE(), 1, GETDATE(), 'CR'
  58. , DBO.FNA_GET_AVAILABLE_BALANCE_POINTS(@CustomerId) + (@registrationPoints/@EquivalentPointsForOne), @registrationPoints
  59. FROM customerMaster (NOLOCK)
  60. WHERE customerId = @CustomerId
  61. UNION
  62. SELECT @CustomerId,@ReferralId, membershipId, 'REGISTRATION', @ReferralId, 'REFER_EARN', @registrationPoints/@EquivalentPointsForOne, GETDATE(), 1, GETDATE(), 'CR'
  63. , DBO.FNA_GET_AVAILABLE_BALANCE_POINTS(@ReferralId) + (@registrationPoints/@EquivalentPointsForOne), @registrationPoints
  64. FROM customerMaster (NOLOCK)
  65. WHERE customerId = @ReferralId
  66. UPDATE customerMaster SET bonusPoint = ISNULL(bonusPoint, 0) + @registrationPoints WHERE customerId = @CustomerId
  67. UPDATE customerMaster SET bonusPoint = ISNULL(bonusPoint, 0) + @registrationPoints WHERE customerId = @ReferralId
  68. END
  69. ELSE IF @Flag = 'TRANSACTION'
  70. BEGIN
  71. --@CustomerId = Customer who is doing transaction
  72. --EXEC proc_InsertRewardPoints @Flag = 'TRANSACTION', @CustomerId = 1, @TranId = 1234567890
  73. IF EXISTS(SELECT 'X' FROM REMITTRAN(NOLOCK) WHERE ID = @TranID)
  74. BEGIN
  75. print 'A';
  76. SELECT @sourceCustomerId = sourceCustomerId, @destinationCustomerId = ISNULL(destinationCustomerId,0)
  77. FROM Customer_Promotion (NOLOCK)
  78. WHERE destinationCustomerId = @CustomerId
  79. and codeTYPE = 'REGISTRATION' and rewardType='REFER_EARN';
  80. IF ISNULL(@destinationCustomerId, 0) <> 0
  81. BEGIN
  82. IF NOT EXISTS(SELECT 'X' FROM Customer_Promotion(NOLOCK) WHERE codeTYPE = 'FIRST_TXN' AND destinationCustomerId = @CustomerId)
  83. BEGIN
  84. INSERT INTO Customer_Promotion(sourceCustomerId, destinationCustomerId, code, codeType, referenceId, rewardType, amount, createdDate, status, approvedDate, tranType, runningBalance, EquivalentPoints)
  85. SELECT @sourceCustomerId, @destinationCustomerId, membershipId, 'FIRST_TXN', @TranId, 'REFER_EARN', @transactionPoints/@EquivalentPointsForOne, GETDATE(), 1, GETDATE(), 'CR'
  86. , DBO.FNA_GET_AVAILABLE_BALANCE_POINTS(@destinationCustomerId) + (@transactionPoints/@EquivalentPointsForOne), @transactionPoints
  87. FROM customerMaster (NOLOCK)
  88. WHERE customerId = @destinationCustomerId
  89. UNION
  90. SELECT @destinationCustomerId, @sourceCustomerId, membershipId, 'FIRST_TXN', @TranId, 'REFER_EARN', @transactionPoints/@EquivalentPointsForOne, GETDATE(), 1, GETDATE(), 'CR'
  91. , DBO.FNA_GET_AVAILABLE_BALANCE_POINTS(@sourceCustomerId) + (@transactionPoints/@EquivalentPointsForOne), @transactionPoints
  92. FROM customerMaster (NOLOCK)
  93. WHERE customerId = @sourceCustomerId
  94. UPDATE customerMaster SET bonusPoint = ISNULL(bonusPoint, 0) + @transactionPoints WHERE customerId = @sourceCustomerId
  95. UPDATE customerMaster SET bonusPoint = ISNULL(bonusPoint, 0) + @transactionPoints WHERE customerId = @destinationCustomerId
  96. END
  97. END
  98. END
  99. END
  100. ELSE IF @Flag = 'DEBIT'
  101. BEGIN
  102. IF ISNULL(@rewardPoints, 0) > 0
  103. BEGIN
  104. --@CustomerId = Customer who is doing transaction
  105. --EXEC proc_InsertRewardPoints @Flag = 'DEBIT', @CustomerId = 1, @rewardPoints = 100, @TranId = 1234567890
  106. SELECT @AvailableBalance = DBO.FNA_GET_AVAILABLE_BALANCE_POINTS(@CustomerId)
  107. IF ISNULL(@rewardPoints, 0) > ISNULL(@AvailableBalance, 0)
  108. BEGIN
  109. SELECT 1 Code, 'Insufficient Balance For Redeem!' msg, NULL id
  110. RETURN;
  111. END
  112. INSERT INTO Customer_Promotion(sourceCustomerId, destinationCustomerId, code, codeType, referenceId, rewardType, amount, createdDate, status, approvedDate, tranType, runningBalance, EquivalentPoints)
  113. SELECT @CustomerId, 0, membershipId, 'REDEEM', @TranId, 'REFER_EARN', @rewardPoints, GETDATE(), 1, GETDATE(), 'DR'
  114. , DBO.FNA_GET_AVAILABLE_BALANCE_POINTS(@CustomerId) - @rewardPoints, @rewardPoints * @EquivalentPointsForOne
  115. FROM customerMaster (NOLOCK)
  116. WHERE customerId = @CustomerId
  117. UPDATE customerMaster SET bonusPoint = ISNULL(bonusPoint, 0) - @rewardPoints WHERE customerId = @CustomerId
  118. END
  119. END
  120. ELSE IF @Flag = 'CREDIT'
  121. BEGIN
  122. IF ISNULL(@rewardPoints, 0) > 0
  123. BEGIN
  124. --@CustomerId = Customer who is doing transaction
  125. --EXEC proc_InsertRewardPoints @Flag = 'DEBIT', @CustomerId = 1, @rewardPoints = 100, @TranId = 1234567890
  126. SELECT @AvailableBalance = DBO.FNA_GET_AVAILABLE_BALANCE_POINTS(@CustomerId)
  127. IF @type = 'CANCEL'
  128. BEGIN
  129. SELECT @rewardPoints = rewardPoints FROM remitTran WHERE id = @TranId
  130. INSERT INTO Customer_Promotion(sourceCustomerId, destinationCustomerId, code, codeType, referenceId, rewardType, amount, createdDate, status, approvedDate, tranType, runningBalance, EquivalentPoints)
  131. SELECT @CustomerId, 0, membershipId, 'REDEEM', @TranId, 'CANCEL_REFUND', @rewardPoints, GETDATE(), 1, GETDATE(), 'CR'
  132. , DBO.FNA_GET_AVAILABLE_BALANCE_POINTS(@CustomerId) - @rewardPoints, @rewardPoints * @EquivalentPointsForOne
  133. FROM customerMaster (NOLOCK)
  134. WHERE customerId = @CustomerId
  135. UPDATE customerMaster SET bonusPoint = ISNULL(bonusPoint, 0) + @rewardPoints WHERE customerId = @CustomerId
  136. END
  137. ELSE IF @type = 'REJECT'
  138. BEGIN
  139. SELECT @rewardPoints = rewardPoints FROM remitTranTemp WHERE id = @TranId
  140. INSERT INTO Customer_Promotion(sourceCustomerId, destinationCustomerId, code, codeType, referenceId, rewardType, amount, createdDate, status, approvedDate, tranType, runningBalance, EquivalentPoints)
  141. SELECT @CustomerId, 0, membershipId, 'REDEEM', @TranId, 'REJECT_REFUND', @rewardPoints, GETDATE(), 1, GETDATE(), 'CR'
  142. , DBO.FNA_GET_AVAILABLE_BALANCE_POINTS(@CustomerId) - @rewardPoints, @rewardPoints * @EquivalentPointsForOne
  143. FROM customerMaster (NOLOCK)
  144. WHERE customerId = @CustomerId
  145. UPDATE customerMaster SET bonusPoint = ISNULL(bonusPoint, 0) + @rewardPoints WHERE customerId = @CustomerId
  146. END
  147. END
  148. END
  149. ELSE IF @flag = 'GET'
  150. BEGIN
  151. IF @sortBy IS NULL
  152. SET @sortBy = 'RowId'
  153. IF @sortOrder IS NULL
  154. SET @sortOrder = 'ASC'
  155. SET @table = '(SELECT RowId, Points, PromotionType, IsActive FROM TBL_PROMOTION_SETUP WHERE isActive = 1)x'
  156. SET @sql_filter = ''
  157. SET @select_field_list ='
  158. RowId
  159. ,Points
  160. ,PromotionType
  161. ,isActive
  162. '
  163. EXEC dbo.proc_paging
  164. @table
  165. ,@sql_filter
  166. ,@select_field_list
  167. ,@extra_field_list
  168. ,@sortBy
  169. ,@sortOrder
  170. ,@pageSize
  171. ,@pageNumber
  172. END
  173. ELSE IF @flag = 'editById'
  174. BEGIN
  175. SELECT * FROM TBL_PROMOTION_SETUP WHERE PromotionType = @promotionType AND isActive = 1
  176. END
  177. ELSE IF @flag = 'GET-MASTER'
  178. BEGIN
  179. IF @sortBy IS NULL
  180. SET @sortBy = 'RowId'
  181. IF @sortOrder IS NULL
  182. SET @sortOrder = 'ASC'
  183. SET @table = '(SELECT * FROM TBL_PROMOTION_MASTER_SETUP WHERE isActive = 1)x'
  184. SET @sql_filter = ''
  185. SET @select_field_list ='
  186. RowId
  187. ,Points
  188. ,isActive
  189. '
  190. EXEC dbo.proc_paging
  191. @table
  192. ,@sql_filter
  193. ,@select_field_list
  194. ,@extra_field_list
  195. ,@sortBy
  196. ,@sortOrder
  197. ,@pageSize
  198. ,@pageNumber
  199. END
  200. ELSE IF @flag = 'UPDATE-POINT'
  201. BEGIN
  202. SELECT @oldPoints = Points FROM TBL_PROMOTION_SETUP WHERE PromotionType = @promotionType
  203. IF EXISTS (SELECT 'X' FROM TBL_PROMOTION_SETUP WHERE PromotionType = @promotionType)
  204. BEGIN
  205. UPDATE TBL_PROMOTION_SETUP SET
  206. Points = @newPoints
  207. ,UpdatedBy = @user
  208. ,UpdatedDate = GETDATE()
  209. ,IsActive = '1'
  210. WHERE PromotionType = @promotionType
  211. SELECT 0 error_code, 'Reward Amount updated successfully.' mes, @newPoints id
  212. END
  213. ELSE
  214. BEGIN
  215. INSERT INTO TBL_PROMOTION_SETUP VALUES (@newPoints, @promotionType, '1', @user, GETDATE())
  216. SELECT 0 error_code, 'Reward type added successfully.' mes, @newPoints id
  217. END
  218. EXEC proc_applicationLogs 'i', NULL, 'update', 'TBL_PROMOTION_SETUP', @promotionType, @user, @oldPoints, @newPoints
  219. END
  220. ELSE IF @flag = 'UPDATE-MASTER'
  221. BEGIN
  222. --SELECT @oldPoints = points FROM TBL_PROMOTION_SETUP WHERE RowId = @rowId
  223. UPDATE TBL_PROMOTION_MASTER_SETUP SET
  224. Points = @newPoints
  225. ,UpdatedBy = @user
  226. ,UpdatedDate = GETDATE()
  227. WHERE RowId = @rowId
  228. SELECT 0 error_code, 'Reward Amount updated successfully.' mes, @newPoints id
  229. EXEC proc_applicationLogs 'i', NULL, 'update', 'TBL_PROMOTION_MASTER_SETUP', NULL, @user, @oldPoints, @newPoints
  230. END
  231. ELSE IF @flag = 'DELETE'
  232. BEGIN
  233. BEGIN TRANSACTION
  234. UPDATE TBL_PROMOTION_SETUP SET
  235. IsActive = 0
  236. ,UpdatedBy = @user
  237. ,UpdatedDate=GETDATE()
  238. WHERE PromotionType = @promotionType
  239. IF @@TRANCOUNT > 0
  240. COMMIT TRANSACTION
  241. SELECT 0 error_code, 'Record deleted successfully.' mes, @promotionType id
  242. EXEC proc_applicationLogs 'i', NULL, 'delete', 'TBL_PROMOTION_SETUP', @promotionType, @user, 'ACTIVE', 'INACTIVE/DELETE'
  243. END
  244. END