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.

383 lines
25 KiB

  1. USE [FastMoneyPro_Remit]
  2. GO
  3. /****** Object: StoredProcedure [dbo].[PROC_GET_DASHBOARD_DATA_V2] Script Date: 11/1/2023 9:42:33 AM ******/
  4. SET ANSI_NULLS ON
  5. GO
  6. SET QUOTED_IDENTIFIER ON
  7. GO
  8. --EXEC PROC_GET_DASHBOARD_DATA_V2 @Flag = 'Dashboard'
  9. ALTER PROC [dbo].[PROC_GET_DASHBOARD_DATA_V2] (
  10. @Flag VARCHAR(20)
  11. ,@User VARCHAR(80) = NULL
  12. ,@fromDate VARCHAR(20) = NULL
  13. ,@toDate VARCHAR(20) = NULL
  14. )
  15. AS
  16. -- #9697 - Registered Customer Count Tally
  17. -- #13162 - Tran Count Tally
  18. -- #18970 - changes to show compliance txn on dashboard on the basis of kyc status
  19. -- selected kyc details to show on dashboard
  20. ;
  21. SET NOCOUNT ON;
  22. SET XACT_ABORT ON;
  23. BEGIN
  24. --SET @fromDate= CONVERT(varchar(10),DATEADD(m, DATEDIFF(m, 0, GETDATE()), 0),121);
  25. SET @fromDate = CONVERT(VARCHAR(10), DATEADD(M, - 6, GETDATE()), 121);
  26. SET @toDate = CONVERT(VARCHAR(10), GETDATE(), 121) + ' 23:59:59';
  27. --set @fromDate = convert(varchar(10) , @fromDate , 121)
  28. --set @toDate = convert(varchar(10) , @toDate , 121)
  29. DECLARE @StartDatePrevious DATETIME
  30. ,@EndDatePrevious DATETIME
  31. SET @StartDatePrevious = dateadd(mm, - 1, getdate())
  32. SET @StartDatePrevious = dateadd(dd, datepart(dd, getdate()) * - 1, @StartDatePrevious)
  33. SET @EndDatePrevious = dateadd(mm, 1, @StartDatePrevious)
  34. IF @Flag = 'Dashboard'
  35. BEGIN
  36. SELECT TOP 50000 CONVERT(VARCHAR(30), RT.approvedDate, 110) createdDate
  37. ,RT.approvedDate AS createdDate1
  38. ,sAgent
  39. ,sAgentName = AM.agentName
  40. ,pCountry
  41. ,tranType
  42. ,tranStatus
  43. ,payStatus
  44. ,CONVERT(VARCHAR(30), paidDate, 110) paidDate
  45. ,CONVERT(VARCHAR(30), cancelApprovedDate, 110) cancelApprovedDate
  46. ,LEFT(DATENAME(MONTH, RT.approvedDate), 3) monthNameTxn
  47. ,DATEPART(MONTH, RT.approvedDate) MonthId
  48. ,id
  49. ,ISNULL(AM.actAsBranch, 'N') actAsBranch
  50. ,ISNULL(RT.createdBy, 'N/A') createdBy
  51. INTO #TXN_TABLE
  52. FROM remitTran RT(NOLOCK)
  53. INNER JOIN agentMaster AM(NOLOCK) ON AM.agentId = RT.sAgent
  54. WHERE RT.approvedDate BETWEEN @fromDate
  55. AND @toDate
  56. AND RT.tranStatus <> 'cancel'
  57. ORDER BY RT.id DESC
  58. SELECT *
  59. FROM #TXN_TABLE RT
  60. WHERE createdDate1 BETWEEN CONVERT(VARCHAR(10), DATEADD(m, DATEDIFF(m, 0, GETDATE()), 0), 121)
  61. AND @toDate
  62. ORDER BY MonthId ASC
  63. --OFAC and Compliance Data
  64. SELECT [Head] = CASE
  65. WHEN TRANTYPE = 'I'
  66. THEN 'OFAC/Compliance/Cash Limit Hold : International'
  67. ELSE 'OFAC/Compliance/Cash Limit Hold : Mobile'
  68. END
  69. ,[Count] = COUNT('x') --CASE WHEN COUNT('x') > 0 THEN '<a href="List.aspx?tranType='+TRANTYPE+'">'+CAST(COUNT('x') AS VARCHAR) +'</a>' ELSE '-' END
  70. FROM remitTranTemp b WITH (NOLOCK)
  71. WHERE B.tranStatus IN (
  72. 'Compliance Hold'
  73. ,'OFAC Hold'
  74. ,'OFAC/Compliance Hold'
  75. ,'Cash Limit Hold'
  76. ,'Cash Limit/OFAC/Compliance Hold'
  77. ,'Cash Limit/OFAC Hold'
  78. ,'Cash Limit/Compliance Hold'
  79. )
  80. GROUP BY TRANTYPE
  81. UNION ALL
  82. SELECT [Head] = CASE
  83. WHEN TRANTYPE = 'I'
  84. THEN 'OFAC/Compliance/Cash Limit Hold : International'
  85. ELSE 'OFAC/Compliance/Cash Limit Hold : Mobile (KYC Later)'
  86. END
  87. ,[Count] = COUNT('x') -- CASE WHEN COUNT('x') > 0 THEN '<a href="List.aspx?tranType='' + TRANTYPE + ''&kycstatus='' + cm.LawsonCardNo + ''">' + CAST(COUNT('x') AS VARCHAR) + '</a>' ELSE '-' END
  88. FROM remitTranTemp b WITH (NOLOCK)
  89. LEFT JOIN transenderstemp tst(NOLOCK) ON b.id = tst.tranId
  90. LEFT JOIN customerMaster cm(NOLOCK) ON tst.customerId = cm.customerId
  91. WHERE cm.LawsonCardNo = 'KYC_LATER'
  92. AND B.tranStatus IN (
  93. 'Compliance Hold'
  94. ,'OFAC Hold'
  95. ,'OFAC/Compliance Hold'
  96. ,'Cash Limit Hold'
  97. ,'Cash Limit/OFAC/Compliance Hold'
  98. ,'Cash Limit/OFAC Hold'
  99. ,'Cash Limit/Compliance Hold'
  100. )
  101. GROUP BY TRANTYPE
  102. ,cm.LawsonCardNo
  103. UNION ALL
  104. SELECT [Head] = CASE
  105. WHEN TRANTYPE = 'I'
  106. THEN 'OFAC/Compliance/Cash Limit Hold : International'
  107. ELSE 'OFAC/Compliance/Cash Limit Hold : Mobile (KYC Now)'
  108. END
  109. ,[Count] = COUNT('x') --CASE WHEN COUNT('x') > 0 THEN '<a href="List.aspx?tranType='' + TRANTYPE + ''&kycstatus='' + cm.LawsonCardNo + ''">' + CAST(COUNT('x') AS VARCHAR) + '</a>' ELSE '-' END
  110. FROM remitTranTemp b WITH (NOLOCK)
  111. LEFT JOIN transenderstemp tst(NOLOCK) ON b.id = tst.tranId
  112. LEFT JOIN customerMaster cm(NOLOCK) ON tst.customerId = cm.customerId
  113. WHERE cm.LawsonCardNo = 'KYC_NOW'
  114. AND B.tranStatus IN (
  115. 'Compliance Hold'
  116. ,'OFAC Hold'
  117. ,'OFAC/Compliance Hold'
  118. ,'Cash Limit Hold'
  119. ,'Cash Limit/OFAC/Compliance Hold'
  120. ,'Cash Limit/OFAC Hold'
  121. ,'Cash Limit/Compliance Hold'
  122. )
  123. GROUP BY TRANTYPE
  124. ,cm.LawsonCardNo
  125. UNION ALL
  126. SELECT [Head] = 'OFAC Pay'
  127. ,[Count] = COUNT('x') --CASE WHEN COUNT('x') > 0 THEN '<a href="PayTranOfacList.aspx">'+CAST(COUNT('x') AS VARCHAR) +'</a>' ELSE '-' END
  128. FROM tranPayOfac rto WITH (NOLOCK)
  129. LEFT JOIN dbo.agentMaster am WITH (NOLOCK) ON rto.pBranch = am.agentId
  130. WHERE rto.approvedDate IS NULL
  131. UNION ALL
  132. SELECT [Head] = 'Compliance Pay'
  133. ,[Count] = COUNT('x') --CASE WHEN COUNT('x') > 0 THEN '<a href="PayTranComplianceList.aspx">'+CAST(COUNT('x') AS VARCHAR) +'</a>' ELSE '-' END
  134. FROM tranPayCompliance rtc WITH (NOLOCK)
  135. LEFT JOIN dbo.agentMaster am WITH (NOLOCK) ON rtc.pBranch = am.agentId
  136. WHERE rtc.approvedDate IS NULL
  137. DECLARE @totalmobileCustomer INT;
  138. DECLARE @todayMobileRegistration INT;
  139. DECLARE @todayMobileActivation INT;
  140. SELECT @totalmobileCustomer = COUNT(cm.CUSTOMERID)
  141. ,@todayMobileRegistration = SUM(CASE
  142. WHEN (
  143. CAST(mobileApprovedDate AS DATE) = CAST(GETDATE() AS DATE)
  144. AND ISNULL(cm.customerStatus, '') <> 'OTC'
  145. )
  146. THEN 1
  147. ELSE 0
  148. END)
  149. FROM CUSTOMERMASTER cm
  150. INNER JOIN mobile_userRegistration mu(NOLOCK) ON mu.username = cm.email
  151. AND cm.customerId = mu.customerId
  152. WHERE cm.mobileApprovedDate IS NOT NULL --and CAST(mobileApprovedDate AS DATE) = CAST(GETDATE() AS DATE)
  153. SELECT @todayMobileActivation = COUNT(cm.customerId)
  154. FROM CUSTOMERMASTER cm
  155. INNER JOIN mobile_userRegistration mu(NOLOCK) ON mu.username = cm.email
  156. AND cm.customerId = mu.customerId
  157. WHERE ISNULL(cm.customerStatus, '') = 'OTC'
  158. AND CAST(mobileApprovedDate AS DATE) = CAST(GETDATE() AS DATE)
  159. AND cm.serviceusedfor = 'CM'
  160. SELECT TotalCustomers = COUNT('X')
  161. ,MobileCustomers = @totalmobileCustomer
  162. ,TodaysMobileRegistration = @todayMobileRegistration
  163. ,TodayMobileActivation = ISNULL(@todayMobileActivation, 0)
  164. ,TodaysRegistration = SUM(CASE
  165. WHEN CAST(approvedDate AS DATE) = CAST(GETDATE() AS DATE)
  166. THEN 1
  167. ELSE 0
  168. END)
  169. FROM customerMaster(NOLOCK)
  170. WHERE approveddate IS NOT NULL
  171. --Lawson summary
  172. DROP TABLE
  173. IF EXISTS #TEMP_SUMMARY
  174. CREATE TABLE #TEMP_SUMMARY (
  175. SN INT
  176. ,lDescription VARCHAR(100)
  177. ,lCount INT
  178. )
  179. DROP TABLE
  180. IF EXISTS #TEMP_PIN
  181. SELECT DISTINCT PIN_NUMBER
  182. INTO #TEMP_PIN
  183. FROM TBL_UNTRANSACTED_TXN(NOLOCK)
  184. WHERE RECORD_TYPE = 'LC'
  185. INSERT INTO #TEMP_SUMMARY (
  186. SN
  187. ,lDescription
  188. ,lCount
  189. )
  190. SELECT 1
  191. ,'Laswon Cards Issued Today'
  192. ,COUNT(cardNumber)
  193. FROM LawsonCard(NOLOCK) l
  194. INNER JOIN customerMaster(NOLOCK) CM ON CM.LawsonCardNo = L.cardNumber
  195. WHERE isUsed = 'Y'
  196. AND CONVERT(VARCHAR, assignedDate, 23) = CONVERT(VARCHAR, GETDATE(), 23)
  197. INSERT INTO #TEMP_SUMMARY (
  198. SN
  199. ,lDescription
  200. ,lCount
  201. )
  202. SELECT 2
  203. ,'Total Lawson Cards Issued'
  204. ,COUNT(cardNumber)
  205. FROM LawsonCard(NOLOCK) L
  206. INNER JOIN customerMaster(NOLOCK) CM ON CM.LawsonCardNo = L.cardNumber
  207. WHERE isUsed = 'Y'
  208. --and CONVERT(VARCHAR, assignedDate, 23) BETWEEN @fromDate AND @toDate
  209. INSERT INTO #TEMP_SUMMARY (
  210. SN
  211. ,lDescription
  212. ,lCount
  213. )
  214. SELECT 3
  215. ,'Total Cards with at least 1 Deposit'
  216. ,COUNT(x.particulars)
  217. FROM (
  218. SELECT particulars
  219. ,COUNT(particulars) AS depositCount
  220. FROM LAWSON_DEPOSIT_LOGS(NOLOCK) DL
  221. INNER JOIN LawsonCard(NOLOCK) l ON l.cardNumber = DL.particulars
  222. --AND CONVERT(VARCHAR, DL.tranDate, 23) BETWEEN @fromDate AND @toDate
  223. WHERE L.isUsed = 'Y'
  224. GROUP BY particulars
  225. HAVING COUNT(particulars) > 1
  226. ) x
  227. INSERT INTO #TEMP_SUMMARY (
  228. SN
  229. ,lDescription
  230. ,lCount
  231. )
  232. SELECT 4
  233. ,'Total Cards with more than 3 transactions'
  234. ,count(totalCount)
  235. FROM (
  236. SELECT DISTINCT CUSTOMER
  237. ,COUNT(T.PIN_NUMBER) AS totalCount
  238. FROM TBL_UNTRANSACTED U(NOLOCK)
  239. INNER JOIN TBL_UNTRANSACTED_TXN UT(NOLOCK) ON UT.TRAN_ID = U.TRAN_ID
  240. INNER JOIN #TEMP_PIN T ON T.PIN_NUMBER = UT.PIN_NUMBER
  241. WHERE U.RECORD_TYPE = 'LC'
  242. --AND ut.TXN_DATE BETWEEN @fromDate AND @toDate
  243. GROUP BY U.CUSTOMER
  244. HAVING COUNT(T.PIN_NUMBER) > 3
  245. ) y
  246. SELECT *
  247. FROM #TEMP_SUMMARY
  248. SELECT *
  249. FROM (
  250. SELECT count(*) RegCount
  251. ,[Day] = CONVERT(VARCHAR(10), approveddate, 121)
  252. ,'C' CustomerType
  253. FROM customerMaster(NOLOCK)
  254. WHERE approveddate IS NOT NULL
  255. AND ISNULL(approveddate, mobileApprovedDate) BETWEEN DATEADD(D, - 15, GETDATE())
  256. AND GETDATE()
  257. GROUP BY CONVERT(VARCHAR(10), approveddate, 121)
  258. UNION ALL
  259. SELECT count(*) RegCount
  260. ,[Day] = CONVERT(VARCHAR(10), mobileApprovedDate, 121)
  261. ,'M' CustomerType
  262. FROM customerMaster cm
  263. INNER JOIN mobile_userRegistration mu(NOLOCK) ON mu.username = cm.email
  264. AND cm.customerId = mu.customerId
  265. WHERE mobileApprovedDate IS NOT NULL
  266. AND mobileApprovedDate BETWEEN DATEADD(D, - 15, GETDATE())
  267. AND GETDATE()
  268. AND ISNULL(cm.customerStatus, '') <> 'OTC'
  269. GROUP BY CONVERT(VARCHAR(10), mobileApprovedDate, 121)
  270. UNION ALL
  271. SELECT count(*) RegCount
  272. ,[Day] = CONVERT(VARCHAR(10), mobileApprovedDate, 121)
  273. ,'A' CustomerType
  274. FROM CUSTOMERMASTER cm
  275. INNER JOIN mobile_userRegistration mu(NOLOCK) ON mu.username = cm.email
  276. AND cm.customerId = mu.customerId
  277. WHERE ISNULL(cm.customerStatus, '') = 'OTC'
  278. AND mobileApprovedDate BETWEEN DATEADD(D, - 15, GETDATE())
  279. AND GETDATE()
  280. AND cm.serviceusedfor = 'CM'
  281. GROUP BY CONVERT(VARCHAR(10), mobileApprovedDate, 121)
  282. ) x
  283. SELECT *
  284. FROM (
  285. SELECT DATEPART(YEAR, RT.createdDate) YearId
  286. ,LEFT(DATENAME(MONTH, RT.createdDate), 3) month_name
  287. ,DATEPART(MONTH, RT.createdDate) MonthId
  288. ,count(*) [Month_count]
  289. FROM #TXN_TABLE RT
  290. GROUP BY DATEPART(YEAR, RT.createdDate)
  291. ,LEFT(DATENAME(MONTH, RT.createdDate), 3)
  292. ,DATEPART(MONTH, RT.createdDate)
  293. ) x
  294. ORDER BY YearId
  295. ,MonthId ASC
  296. SELECT ISNULL(A.sAgentName, B.sAgentName) sAgentName
  297. ,ISNULL(A.CurrentMonth, 0) CurrentMonth
  298. ,ISNULL(B.PreviousMonth, 0) PreviousMonth
  299. FROM (
  300. SELECT count(c.sAgent) CurrentMonth
  301. ,c.sAgentName
  302. FROM #TXN_TABLE c
  303. WHERE ISNULL(c.actAsBranch, '') = 'N'
  304. AND c.tranStatus <> 'Cancel'
  305. AND C.createdDate1 BETWEEN CONVERT(VARCHAR(10), DATEADD(m, DATEDIFF(m, 0, GETDATE()), 0), 121)
  306. AND @toDate
  307. GROUP BY sAgentName
  308. ) A
  309. LEFT JOIN (
  310. SELECT count(p.sAgent) PreviousMonth
  311. ,p.sAgentName
  312. FROM #TXN_TABLE p
  313. WHERE ISNULL(p.actAsBranch, '') = 'N'
  314. AND p.tranStatus <> 'Cancel'
  315. AND p.createdDate1 BETWEEN @StartDatePrevious
  316. AND @EndDatePrevious
  317. GROUP BY sAgentName
  318. ) B ON a.sAgentName = B.sAgentName
  319. ORDER BY CurrentMonth DESC
  320. --KYC status
  321. SELECT [Head] = ISNULL(verificationCode, 'NOT_COMPLETED')
  322. ,[Count] = COUNT('x') --CASE WHEN COUNT('x') > 0 THEN '<a href="List.aspx?tranType='' + TRANTYPE + ''&kycstatus='' + cm.LawsonCardNo + ''">' + CAST(COUNT('x') AS VARCHAR) + '</a>' ELSE '-' END
  323. FROM customerMaster cm WITH (NOLOCK)
  324. WHERE cm.verificationCode IS NULL OR cm.verificationCode = 'NOT_COMPLETED' --AND DATEDIFF(DAY, cm.createdDate, GETDATE()) <= 7
  325. GROUP BY verificationCode
  326. UNION ALL
  327. SELECT [Head] = verificationCode
  328. ,[Count] = COUNT('x') --CASE WHEN COUNT('x') > 0 THEN '<a href="List.aspx?tranType='' + TRANTYPE + ''&kycstatus='' + cm.LawsonCardNo + ''">' + CAST(COUNT('x') AS VARCHAR) + '</a>' ELSE '-' END
  329. FROM customerMaster cm WITH (NOLOCK)
  330. WHERE cm.verificationCode = 'PROCESSING' --AND DATEDIFF(DAY, cm.createdDate, GETDATE()) <= 7
  331. GROUP BY verificationCode
  332. UNION ALL
  333. SELECT [Head] = verificationCode
  334. ,[Count] = COUNT('x') --CASE WHEN COUNT('x') > 0 THEN '<a href="List.aspx?tranType='' + TRANTYPE + ''&kycstatus='' + cm.LawsonCardNo + ''">' + CAST(COUNT('x') AS VARCHAR) + '</a>' ELSE '-' END
  335. FROM customerMaster cm WITH (NOLOCK)
  336. WHERE cm.verificationCode = 'COMPLETED' --AND DATEDIFF(DAY, cm.createdDate, GETDATE()) <= 7
  337. GROUP BY verificationCode
  338. END
  339. END