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.
 
 
 

208 lines
8.2 KiB

USE [FastMoneyPro_Remit]
GO
/****** Object: StoredProcedure [dbo].[proc_GoldCardReport] Script Date: 7/4/2019 11:35:48 AM ******/
DROP PROCEDURE [dbo].[proc_GoldCardReport]
GO
/****** Object: StoredProcedure [dbo].[proc_GoldCardReport] Script Date: 7/4/2019 11:35:48 AM ******/
SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO
--EXEC proc_customerReport @flag = 'detail-report',@startDate = '10/01/2017',@endDate = '12/31/2018',@user = 'admin',@country = null,@branch = NULL
CREATE PROC [dbo].[proc_GoldCardReport]
(
@flag VARCHAR(50)
,@startDate VARCHAR(30) = NULL
,@endDate VARCHAR(30) = NULL
,@user VARCHAR(30) = NULL
,@country VARCHAR(30) = NULL
,@branch VARCHAR(80) = NULL
,@goldCardNo varchar(20) = NULL
)
AS
SET NOCOUNT ON;
SET XACT_ABORT ON;
BEGIN
IF @flag = 'detail-rpt'
BEGIN
SELECT
GoldCardNumber = cm.membershipId,
IssuedDate = cm.memberIDissuedDate,
IssuedBy = cm.memberIDissuedByUser,
IdNumber = cm.idNumber,
MobileNumber = cm.mobile
FROM dbo.customerMaster CM(NOLOCK)
LEFT JOIN (
SELECT AU.userName, AM.agentName FROM agentMaster AM(NOLOCK)
INNER JOIN applicationUsers AU(NOLOCK) ON AU.agentId = AM.agentId
WHERE AM.agentId = ISNULL(@branch, AM.agentId)
)X ON X.userName = CM.memberIDissuedByUser
INNER JOIN countryMaster C(NOLOCK) ON C.countryId = CM.nativeCountry
WHERE CM.nativeCountry = ISNULL(@country, CM.nativeCountry)
AND X.agentName IS NOT NULL
AND CM.approvedBy IS NOT NULL AND CM.memberIDissuedDate IS NOT NULL
AND CM.memberIDissuedDate BETWEEN @startDate AND @endDate + ' 23:59:59'
AND CM.membershipId = ISNULL(@goldCardNo, CM.membershipId)
EXEC proc_errorHandler '0', 'Report has been prepared successfully.', NULL
select 'Country' head, CASE WHEN @country IS NULL THEN 'All' ELSE (SELECT countryName FROM countryMaster (NOLOCK) WHERE countryId = @country) END UNION ALL
select 'Branch' head, ISNULL((SELECT agentName FROM agentMaster (NOLOCK) WHERE agentId = @branch), 'All') union all-- CASE WHEN @branch IS NULL THEN 'All' ELSE (SELECT agentName FROM agentMaster (NOLOCK) WHERE agentId = @branch) END UNION ALL
SELECT 'GoldCardNumber' head, ISNULL(@goldCardNo, 'All') union all
SELECT 'From Date' head, @startDate value union all
SELECT 'To Date' head, @endDate value
SELECT 'Gold Card Detail Report' title
END
ELSE IF @flag = 'register-matrix'
BEGIN
IF OBJECT_ID('tempdb..#TEMP') IS NOT NULL DROP TABLE #TEMP
CREATE TABLE #TEMP (NAME VARCHAR(50), COUNTRY VARCHAR(30), QTY INT, AGENTID INT)
INSERT INTO #TEMP (NAME , COUNTRY , QTY, AGENTID )
SELECT [NAME] = agentName,
[COUNTRY] = C.countryName,
[QTY] = COUNT(1),
AGENTID = X.agentId
FROM customerMaster CM(NOLOCK)
LEFT JOIN (
SELECT AU.userName, AM.agentName, AM.agentId FROM agentMaster AM(NOLOCK)
INNER JOIN applicationUsers AU(NOLOCK) ON AU.agentId = AM.agentId
WHERE AM.agentId = ISNULL(@branch, AM.agentId)
)X ON X.userName = CM.memberIDissuedByUser
INNER JOIN countryMaster C(NOLOCK) ON C.countryId = CM.nativeCountry
WHERE CM.approvedBy IS NOT NULL
AND X.agentName IS NOT NULL
AND CM.nativeCountry = ISNULL(@country, CM.nativeCountry)
AND CM.memberIDissuedDate BETWEEN @startDate AND @endDate + ' 23:59:59'
AND CM.membershipId = ISNULL(@goldCardNo, CM.membershipId)
GROUP BY X.agentName, C.countryName, X.agentId, C.countryName, CM.nativeCountry
ORDER BY C.countryName
IF NOT EXISTS(SELECT 1 FROM #TEMP)
BEGIN
SELECT SNO = 1, [ERROR_MESSAGE] = 'NO DATA FOUND FOR THIS FILTER'
RETURN
END
DECLARE @columns NVARCHAR(MAX), @sql NVARCHAR(MAX);
SET @columns = '';
SELECT
@columns += N', p.' + QUOTENAME(NAME)
FROM (SELECT DISTINCT NAME FROM #TEMP) AS x;
SET @columns = ', p.Country ' + @columns
SET @sql = N'
SELECT *
FROM
(
SELECT NAME, COUNTRY, QTY = ISNULL(QTY, 0) FROM #TEMP
) AS j
PIVOT
(
SUM(QTY) FOR NAME IN ('
+ STUFF(REPLACE(REPLACE(REPLACE(@columns, 'p.Country ,', ''), ', p.[', ',['), 'p.', ''), 1, 1, '')
+ ')
) AS p;';
PRINT @sql;
EXEC sp_executesql @sql;
END
ELSE IF @flag = 'matrix-detail'
BEGIN
SELECT [CUSTOMER NAME] = firstName,
[EMAIL] = email,
[REGISTERED DATE] = CM.createdDate,
[APPROVED DATE] = CM.verifiedDate,
[BANK NAME] = KB.BankName,
[BANK ACCOUNT NUMBER] = CM.bankAccountNo,
[WALLET ACCOUNT NUMBER] = CM.walletAccountNo,
[AVAILBALE BALANCE] = CM.availableBalance
FROM customerMaster CM(NOLOCK)
LEFT JOIN (
SELECT AU.userName, AM.agentName FROM agentMaster AM(NOLOCK)
INNER JOIN applicationUsers AU(NOLOCK) ON AU.agentId = AM.agentId
WHERE AM.agentName = ISNULL(@branch, AM.agentName)
)X ON X.userName = CM.memberIDissuedByUser
INNER JOIN countryMaster C(NOLOCK) ON C.countryId = CM.nativeCountry
INNER JOIN KoreanBankList KB(NOLOCK) ON KB.rowId = CM.bankName
WHERE C.countryName = ISNULL(@country, C.countryName)
AND X.agentName IS NOT NULL
AND CM.approvedBy IS NOT NULL
AND CM.memberIDissuedDate BETWEEN @startDate AND @endDate + ' 23:59:59'
AND CM.membershipId = ISNULL(@goldCardNo, CM.membershipId)
EXEC proc_errorHandler '0', 'Report has been prepared successfully.', NULL
select 'Country' head, @country UNION ALL
select 'Branch' head, @branch UNION ALL
SELECT 'GoldCardNumber' head, @goldCardNo UNION ALL
SELECT 'From Date' head, @startDate value union all
SELECT 'To Date' head, @endDate value
SELECT 'Gold Card Report' title
END
ELSE IF @flag = 'GRS' --Gold Card report Summary
BEGIN
SELECT '<a href=Reports.aspx?reportName=goldcarddetailreport&startDate=''' +ISNULL( @startDate,'') + '''&endDate=''' + ISNULL(@endDate,'') + '''&country=''' + CAST( cm.nativeCountry AS VARCHAR(10)) + '''&branch=''' +ISNULL( @branch,'') +'''&goldCardNo=''' + cm.referelCode + '''&flag=DRT' + '>' + a.fullName + '</a>' [Name]
,cm.referelCode [Gold Card Number],M.countryName [Nationality], COUNT(1) [Number of register]
FROM customerMaster CM(NOLOCK)
JOIN dbo.countryMaster M (NOLOCK) ON m.countryId = cm.nativeCountry
JOIN (
SELECT membershipId,fullName FROM customerMaster(nolocK) WHERE membershipId=ISNULL( @goldCardNo, membershipId)
) a ON a.membershipId= cm.referelCode
LEFT JOIN (
SELECT AU.userName, AM.agentName FROM agentMaster AM(NOLOCK)
INNER JOIN applicationUsers AU(NOLOCK) ON AU.agentId = AM.agentId
WHERE AM.agentName = ISNULL(@branch, AM.agentName)
)X ON X.userName = CM.memberIDissuedByUser
WHERE CM.referelCode =ISNULL( @goldCardNo,cm.referelCode)
AND CM.approvedBy IS NOT NULL
AND M.countryId = ISNULL(@country, M.countryId)
AND CM.approvedDate BETWEEN @startDate AND @endDate + ' 23:59:59'
GROUP BY a.fullName ,cm.referelCode,M.countryName,cm.nativeCountry
order by cm.nativeCountry
EXEC proc_errorHandler '0', 'Report has been prepared successfully.', NULL
select 'Country' head, @country UNION ALL
select 'Branch' head, @branch UNION ALL
SELECT 'GoldCardNumber' head, @goldCardNo UNION ALL
SELECT 'From Date' head, @startDate value union all
SELECT 'To Date' head, @endDate value
SELECT 'Gold Card Registation Summary Report' title
END
IF @flag = 'DRT' -- Gold card report Details
BEGIN
IF @branch = ''
BEGIN
SET @branch = null
END
SELECT cm.email [Email ID], cm.fullName [Name] ,M.countryName[Native Country], cm.approvedBy [Approved By] FROM customerMaster CM(NOLOCK)
JOIN dbo.countryMaster M (NOLOCK) ON m.countryId = cm.nativeCountry
LEFT JOIN (
SELECT AU.userName, AM.agentName FROM agentMaster AM(NOLOCK)
INNER JOIN applicationUsers AU(NOLOCK) ON AU.agentId = AM.agentId
WHERE AM.agentName = ISNULL(@branch, AM.agentName)
)X ON X.userName = CM.memberIDissuedByUser
WHERE CM.referelCode = @goldCardNo
AND CM.approvedBy IS NOT NULL
AND m.countryId = ISNULL(@country, M.countryId)
AND CM.approvedDate BETWEEN @startDate AND @endDate + ' 23:59:59'
EXEC proc_errorHandler '0', 'Report has been prepared successfully.', NULL
select 'Country' head, @country UNION ALL
select 'Branch' head, @branch UNION ALL
SELECT 'GoldCardNumber' head, @goldCardNo UNION ALL
SELECT 'From Date' head, @startDate value union all
SELECT 'To Date' head, @endDate value
SELECT 'Gold Card Registation Details Report' title
END
END
GO