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.

311 lines
16 KiB

  1. USE [FastMoneyPro_Remit]
  2. GO
  3. /****** Object: StoredProcedure [dbo].[proc_CustomerPromotionReport] Script Date: 1/17/2024 3:18:30 PM ******/
  4. SET ANSI_NULLS ON
  5. GO
  6. SET QUOTED_IDENTIFIER ON
  7. GO
  8. ALTER PROC [dbo].[proc_CustomerPromotionReport] @flag VARCHAR(50)
  9. ,@rowId BIGINT = NULL
  10. ,@sourceCustomerId INT = NULL
  11. ,@user VARCHAR(50) = NULL
  12. ,@pageSize VARCHAR(50) = NULL
  13. ,@pageNumber VARCHAR(50) = NULL
  14. ,@sortBy VARCHAR(50) = NULL
  15. ,@sortOrder VARCHAR(50) = NULL
  16. ,@isActive VARCHAR(20) = NULL
  17. ,@userId VARCHAR(100) = NULL
  18. ,@fromDate VARCHAR(30) = NULL
  19. ,@toDate VARCHAR(30) = NULL
  20. AS
  21. SET NOCOUNT ON;
  22. SET XACT_ABORT ON;
  23. DECLARE @table VARCHAR(MAX)
  24. ,@select_field_list VARCHAR(MAX)
  25. ,@extra_field_list VARCHAR(MAX)
  26. ,@sql_filter VARCHAR(MAX)
  27. ,@ACC_NUM VARCHAR(30)
  28. ,@REFERRAL_CODE VARCHAR(30)
  29. ,@errorMsg VARCHAR(30)
  30. -- -- #1526 - Post production fixes for Redeem & Earn , @FLAG = 'customer-by-referral-report'
  31. -- #24829 change in @FLAG = 'customer-promotion-report' to get correct redeem report
  32. IF @FLAG = 'customer-promotion-report'
  33. BEGIN
  34. IF OBJECT_ID(N'tempdb..#REGCOUNT') IS NOT NULL
  35. BEGIN
  36. DROP TABLE #REGCOUNT
  37. END
  38. CREATE TABLE #REGCOUNT (
  39. sourceCustomerId INT
  40. ,customerName VARCHAR(150)
  41. ,membershipId VARCHAR(50)
  42. ,regCount INT
  43. ,totalBalance MONEY
  44. ,created_Date DATETIME
  45. )
  46. INSERT INTO #REGCOUNT (
  47. sourceCustomerId
  48. ,customerName
  49. ,regCount
  50. ,membershipId
  51. )
  52. SELECT CM.customerId
  53. ,cm.fullName
  54. ,COUNT(destinationCustomerId)
  55. ,cm.membershipId
  56. FROM Customer_Promotion cp(NOLOCK)
  57. INNER JOIN CustomerMaster cm(NOLOCK) ON cm.customerId = cp.sourceCustomerId
  58. WHERE [status] = 1 --AND codeType = 'REGISTRATION'
  59. AND CP.approvedDate BETWEEN @fromDate
  60. AND @toDate + ' 23:59:59'
  61. GROUP BY cm.fullName
  62. ,cm.customerId
  63. ,cm.membershipId
  64. -- update runningBalance
  65. IF OBJECT_ID(N'tempdb..#RUNNINGBALANCE') IS NOT NULL
  66. BEGIN
  67. DROP TABLE #RUNNINGBALANCE
  68. END
  69. CREATE TABLE #RUNNINGBALANCE (
  70. sourceCustomerId INT
  71. ,runningBalance MONEY
  72. )
  73. INSERT INTO #RUNNINGBALANCE
  74. SELECT r.sourceCustomerId
  75. ,isnull(crAmount, 0) - isnull(drAmount, 0)
  76. FROM #REGCOUNT r
  77. LEFT JOIN (
  78. SELECT cm.sourceCustomerId
  79. ,SUM(ISNULL(AMOUNT, 0)) AS drAmount
  80. FROM Customer_Promotion(NOLOCK) cm
  81. WHERE 1 = 1
  82. AND tranType = 'DR'
  83. AND [status] = 1
  84. AND cm.approvedDate BETWEEN @fromDate
  85. AND @toDate + ' 23:59:59'
  86. GROUP BY sourceCustomerId
  87. ) dr ON dr.sourceCustomerId = r.sourceCustomerId
  88. LEFT JOIN (
  89. SELECT cm.sourceCustomerId
  90. ,SUM(ISNULL(AMOUNT, 0)) AS crAmount
  91. FROM Customer_Promotion(NOLOCK) cm
  92. WHERE 1 = 1
  93. AND tranType = 'CR'
  94. AND [status] = 1
  95. AND cm.approvedDate BETWEEN @fromDate
  96. AND @toDate + ' 23:59:59'
  97. GROUP BY sourceCustomerId
  98. ) cr ON cr.sourceCustomerId = r.sourceCustomerId
  99. --UPDATE r SET totalBalance = X.runningBalance , created_Date = X.createdDate
  100. --FROM #REGCOUNT R
  101. --INNER JOIN
  102. -- (
  103. -- SELECT cp.sourceCustomerId,createdDate, CAST(runningBalance AS VARCHAR) runningBalance
  104. -- FROM Customer_Promotion cp
  105. -- --INNER JOIN #REGCOUNT r ON r.sourceCustomerId = cp.sourceCustomerId
  106. -- WHERE createdDate = (SELECT MAX(createdDate) FROM Customer_Promotion cpDate WHERE cp.sourceCustomerId = cpDate.sourceCustomerId)
  107. -- )X ON X.sourceCustomerId = R.sourceCustomerId
  108. UPDATE r
  109. SET created_Date = X.createdDate
  110. ,totalBalance = RB.runningBalance
  111. FROM #REGCOUNT R
  112. INNER JOIN (
  113. SELECT cp.sourceCustomerId
  114. ,createdDate
  115. FROM Customer_Promotion cp
  116. --INNER JOIN #REGCOUNT r ON r.sourceCustomerId = cp.sourceCustomerId
  117. WHERE createdDate = (
  118. SELECT MAX(createdDate)
  119. FROM Customer_Promotion cpDate
  120. WHERE cp.sourceCustomerId = cpDate.sourceCustomerId
  121. )
  122. ) X ON X.sourceCustomerId = R.sourceCustomerId
  123. INNER JOIN #RUNNINGBALANCE RB ON RB.SOURCECUSTOMERID = R.SOURCECUSTOMERID
  124. --select * from #regcount
  125. SELECT ROW_NUMBER() OVER (
  126. ORDER BY CREATED_DATE ASC
  127. ) SN
  128. ,[CUSTOMER] = customerName
  129. ,[MEMBERSHIPID] = membershipId
  130. ,[REWARD POINTS] = '<a href="javascript:void(0)" onclick="OpenInNewWindow(''/RemittanceSystem/RemittanceReports/Reports.aspx?reportName=promotionsummaryreport&fromDate=' + @fromDate + '&toDate=' + @toDate + '&sourceCustomerId=' + CAST(sourceCustomerId AS VARCHAR) + ''');">' + CAST(ISNULL(totalBalance, 0) AS VARCHAR) + '</a>'
  131. FROM #REGCOUNT
  132. EXEC proc_errorHandler '0'
  133. ,'Report has been prepared successfully.'
  134. ,NULL
  135. SELECT 'From Date' head
  136. ,@fromDate VALUE
  137. UNION ALL
  138. SELECT 'To Date' head
  139. ,@toDate VALUE
  140. SELECT 'Customer Promotion Report' title
  141. END
  142. ELSE IF @FLAG = 'customer-promotion-summary'
  143. BEGIN
  144. IF OBJECT_ID('tempdb..#Reward') IS NOT NULL
  145. DROP TABLE #Reward
  146. CREATE TABLE #Reward (
  147. DESTINATION_CUSTOMERID INT
  148. ,REWARD_TYPE VARCHAR(25)
  149. ,REWARD_AMOUNT INT
  150. ,CUSTOMER_NAME VARCHAR(200)
  151. ,CREATED_DATE VARCHAR(10)
  152. ,MEMBERSHIP_ID VARCHAR(50)
  153. )
  154. INSERT INTO #Reward (
  155. DESTINATION_CUSTOMERID
  156. ,REWARD_TYPE
  157. ,REWARD_AMOUNT
  158. ,CREATED_DATE
  159. )
  160. SELECT destinationCustomerId
  161. ,codeType
  162. ,CASE
  163. WHEN trantype = 'DR'
  164. THEN - CAST(ISNULL(AMOUNT, 0) AS INT)
  165. ELSE CAST(ISNULL(AMOUNT, 0) AS INT)
  166. END
  167. ,CONVERT(VARCHAR(10), cp.approvedDate, 121)
  168. FROM Customer_Promotion CP(NOLOCK)
  169. WHERE sourceCustomerId = @sourceCustomerId
  170. AND [STATUS] = 1
  171. AND CP.approvedDate BETWEEN @fromDate
  172. AND @toDate + ' 23:59:59'
  173. UPDATE R
  174. SET CUSTOMER_NAME = ISNULL(fullName, '')
  175. ,MEMBERSHIP_ID = cm.membershipId
  176. FROM #Reward R
  177. INNER JOIN customerMaster CM(NOLOCK) ON R.DESTINATION_CUSTOMERID = customerId
  178. SELECT ROW_NUMBER() OVER (
  179. ORDER BY CREATED_DATE ASC
  180. ) SN
  181. ,[Customer] = CUSTOMER_NAME
  182. ,[MembershipId] = MEMBERSHIP_ID
  183. ,[Created_Date] = CREATED_DATE
  184. ,[Amount] = Reward_Amount
  185. ,[Reward Type] = REWARD_TYPE
  186. FROM #Reward
  187. EXEC proc_errorHandler '0'
  188. ,'Report has been prepared successfully.'
  189. ,NULL
  190. SELECT 'From Date' head
  191. ,@fromDate VALUE
  192. UNION ALL
  193. SELECT 'To Date' head
  194. ,@toDate VALUE
  195. SELECT 'Customer Promotion Summary Report' title
  196. END
  197. ELSE IF @FLAG = 'customer-by-referral-report'
  198. BEGIN
  199. IF OBJECT_ID(N'tempdb..#REFERRAL') IS NOT NULL
  200. BEGIN
  201. DROP TABLE #REFERRAL
  202. END
  203. CREATE TABLE #REFERRAL (
  204. sourceCustomerId INT
  205. ,referralName VARCHAR(150)
  206. ,membershipId VARCHAR(50)
  207. )
  208. INSERT INTO #REFERRAL (
  209. sourceCustomerId
  210. ,referralName
  211. ,membershipId
  212. )
  213. SELECT CM.customerId
  214. ,cm.fullName
  215. ,cm.membershipId
  216. FROM Customer_Promotion cp(NOLOCK)
  217. INNER JOIN CustomerMaster cm(NOLOCK) ON cm.customerId = cp.sourceCustomerId
  218. WHERE [status] = 1
  219. AND codeType = 'REGISTRATION'
  220. AND CP.approvedDate BETWEEN @fromDate
  221. AND @toDate + ' 23:59:59'
  222. GROUP BY cm.customerid
  223. ,cm.fullName
  224. ,cm.membershipId
  225. IF OBJECT_ID(N'tempdb..#CUSTOMER') IS NOT NULL
  226. BEGIN
  227. DROP TABLE #CUSTOMER
  228. END
  229. CREATE TABLE #CUSTOMER (
  230. destinationCustomerId INT
  231. ,customerName VARCHAR(150)
  232. ,membershipId VARCHAR(50)
  233. ,referralCode VARCHAR(50)
  234. ,isExistingCustomer CHAR(1)
  235. ,createdDate DATETIME
  236. ,mobileRegisteredDate DATETIME
  237. )
  238. INSERT INTO #CUSTOMER
  239. SELECT CM.customerId
  240. ,cm.fullName
  241. ,cm.membershipId
  242. ,CM.referelCode
  243. ,isexistingcustomer
  244. ,CM.createdDate
  245. ,mobileApprovedDate
  246. FROM Customer_Promotion cp(NOLOCK)
  247. INNER JOIN CustomerMaster cm(NOLOCK) ON cm.customerId = cp.destinationCustomerId
  248. WHERE [status] = 1
  249. AND codeType = 'REGISTRATION'
  250. AND CP.approvedDate BETWEEN @fromDate
  251. AND @toDate + ' 23:59:59'
  252. SELECT ROW_NUMBER() OVER (
  253. ORDER BY mobileRegisteredDate DESC
  254. ) SN
  255. ,[Referral MembershipId] = r.membershipId
  256. ,[Referral Name] = r.referralName
  257. ,[Customer MembershipId] = c.membershipId
  258. ,[Customer Name] = c.customerName
  259. --, [Existing Customer] = CASE WHEN ISNULL(c.isExistingCustomer , 1) = 1 THEN 'Y' ELSE 'N' END
  260. ,[Created Date] = c.createdDate
  261. ,[Mobile Registered Date] = c.mobileRegisteredDate
  262. FROM #REFERRAL R
  263. INNER JOIN #CUSTOMER C ON R.MEMBERSHIPID = C.referralCode
  264. EXEC proc_errorHandler '0'
  265. ,'Report has been prepared successfully.'
  266. ,NULL
  267. SELECT 'From Date' head
  268. ,@fromDate VALUE
  269. UNION ALL
  270. SELECT 'To Date' head
  271. ,@toDate VALUE
  272. SELECT 'Redeem & Earn Report Report' title
  273. END