IF object_id('dbo.PRptMemberReport','P') IS NOT NULL BEGIN DROP PROCEDURE dbo.PRptMemberReport END GO CREATE PROCEDURE PRptMemberReport ( @IParam VARCHAR(8000) --参数 ) AS BEGIN -- exec PDropTempTables --IF object_id('#Member') IS NOT NULL --BEGIN -- DROP TABLE #Member --END CREATE TABLE #Member ( --FSId INT NOT NULL, FCompId BIGINT NOT NULL, FMemId BIGINT NOT NULL, FMemNo VARCHAR(30) NOT NULL, --会员编号 FName VARCHAR(50) NOT NULL, --会员姓名 FCompNo VARCHAR(30) NOT NULL, --归属公司 FGender INT NOT NULL, --性别 FMobilePhone VARCHAR(30) NOT NULL, --手机号码 FBirthday VARCHAR(30) NULL, -- 生日 FBirthdayType CHAR NOT NULL, --生日类型 FJoinDate VARCHAR(30) NOT NULL, --入会日期 FRchgAmt DECIMAL(18,6) NOT NULL DEFAULT 0, --累计充值 FConsAmt DECIMAL(18,6) NOT NULL DEFAULT 0, --累计消费 FConsTimes INT NOT NULL DEFAULT 0, --消费总次数 FLastDate VARCHAR(10) NULL, --最后消费日期 FPoint DECIMAL(18,6) NOT NULL DEFAULT 0, --积分 FConsArrear DECIMAL(18,6) NOT NULL DEFAULT 0,--消费欠款 FConsPrice DECIMAL(18,6) NOT NULL DEFAULT 0, FCourseArrear DECIMAL(18,6) NOT NULL DEFAULT 0, FFavoriteEmpName VARCHAR(100), --喜爱的发型师 FSaleEmpName VARCHAR(100), --销售者 FChargeEmpId BIGINT --负责员工 PRIMARY KEY(FMemId) ) --=IF object_id('dbo.#MemberCard') IS NOT NULL --BEGIN -- DROP TABLE #MemberCard --END CREATE TABLE #MemberCard ( -- FSId INT NOT NULL, --登录id FCardId BIGINT NOT NULL, --卡Id FCardNo VARCHAR(30) NOT NULL, --卡号 FMemId BIGINT NOT NULL, --会员Id FMemNo VARCHAR(30) NOT NULL, --会员编号 FCompId BIGINT NOT NULL, --公司Id FCardTypeId BIGINT NOT NULL, FCardTypeNo VARCHAR(20) NOT NULL, --类别 FCardTypeName VARCHAR(50) NOT NULL, --类别名称 FCreateDate VARCHAR(10) NOT NULL, --买卡日期 FExpiredDate VARCHAR(10) NULL, --有效期 FRemainTimes INT, --剩余次数 FState INT, --状态 FCalcMode INT, FItemId BIGINT DEFAULT 0, FIsCourse BIT DEFAULT 0 , PRIMARY KEY(FCardId) ) CREATE TABLE #MemberCourse ( FCourseName VARCHAR(100), FCompId BIGINT, FCreateDate VARCHAR(10), FExpiredDate VARCHAR(10), FRemainTimes FLOAT, FCalcMode INT, FStateName VARCHAR(10) ) --生成账户字段 --DECLARE @Sql VARCHAR(8000) --SELECT @Sql = ' ALTER TABLE #MemberCard ADD ' --SELECT @Sql = @Sql + ' FAcct' + FNo + ' DECIMAL(18,6) NOT NULL DEFAULT 0 ,' -- FROM TPayAccount WITH(NOLOCK) -- WHERE FIsAccount = 1 --SELECT @Sql = SUBSTRING(@Sql,0,LEN(@Sql)-1) --EXEC (@Sql) DECLARE @SId INT DECLARE @CompanyForCard BIT --使用卡归属公司 DECLARE @MemCompNo VARCHAR(1000) --会员公司 DECLARE @CompSource INT --公司 DECLARE @ShowCardInfo BIT --显示卡 DECLARE @ShowCourseInfo INT --显示疗程 -- DECLARE @CardCompNo VARCHAR(1000)--储值卡公司 DECLARE @CompanyStr VARCHAR(1000)--公司 DECLARE @FromMemNo VARCHAR(30) --开始会员编号 DECLARE @ToMemNo VARCHAR(30) --结束会员编号 DECLARE @MemName VARCHAR(50) --会员姓名 DECLARE @MobilePhone VARCHAR(20) --手机号码 DECLARE @FromBirthday VARCHAR(20)--开始生日 1-0121 DECLARE @ToBirthday VARCHAR(20) --结束生日 1-0212 DECLARE @FromJoinDate DATETIME --开始加入日期 DECLARE @ToJoinDate DATETIME --截至加入日期 DECLARE @Gender INT --性别 DECLARE @FromPoint DECIMAL(18,6) --开始积分 DECLARE @ToPoint DECIMAL(18,6) --结束积分 DECLARE @FromLastDate VARCHAR(10)--最后消费日期 DECLARE @ToLastDate VARCHAR(10) -- DECLARE @AfterLastDate VARCHAR(10) -- DECLARE @FromConsTimes INT --消费总次数 DECLARE @ToConsTimes INT DECLARE @FromConsAmt DECIMAL(18,6)--消费总额 DECLARE @ToConsAmt DECIMAL(18,6) -- DECLARE @FromRchgAmt DECIMAL(18,6) DECLARE @ToRchgAmt DECIMAL(18,6) DECLARE @NotComeDay INT --多少天没有来的 DECLARE @FromStatDate VARCHAR(10) --消费统计日期 DECLARE @ToStatDate VARCHAR(10) --消费统计日期 DECLARE @FromCardNo VARCHAR(30) --开始会员卡号 DECLARE @ToCardNo VARCHAR(30) --结束会员卡号 DECLARE @CardTypeNo VARCHAR(20) DECLARE @FromCardCreateDate DATETIME --开卡日期 DECLARE @ToCardCreateDate DATETIME DECLARE @FromCardExpiredDate DATETIME --截至日期 DECLARE @ToCardExpiredDate DATETIME --截至日期 DECLARE @FromRemainTimes INT --剩余次数 DECLARE @ToRemainTimes INT --剩余次数 DECLARE @CardState INT --卡状态 DECLARE @AcctNo VARCHAR(30) --账户 DECLARE @FromBalance DECIMAL(18,6) --余额 DECLARE @ToBalance DECIMAL(18,6) --余额 DECLARE @CardExpired INT --储值卡是否过期 -1过期,0全部,1未过期 DECLARE @ChargeEmpNo VARCHAR(20) --负责业务 DECLARE @ChargeEmpId BIGINT --疗程条件 DECLARE @CourseNo VARCHAR(1000) DECLARE @FromCourseRemainTimes INT DECLARE @ToCourseRemainTimes INT SELECT @MemCompNo = dbo.FNGetParamValue(@IParam,'CompNo'); SELECT @CompSource = dbo.FNGetParamValue(@IParam,'CompSource'); --SELECT @CardCompNo = dbo.FNGetParamValue(@IParam,'CardCompNo'); --SELECT @SId = dbo.FNGetParamValue(@IParam,'SId'); SELECT @ShowCardInfo = ISNULL(dbo.FNGetParamValue(@IParam,'ShowCardInfo'),1); SELECT @ShowCourseInfo = ISNULL(dbo.FNGetParamValue(@IParam,'ShowCourseInfo'),0); SELECT @FromMemNo = ISNULL(dbo.FNGetParamValue(@IParam,'FromMemNo'),''); SELECT @ToMemNo = ISNULL(dbo.FNGetParamValue(@IParam,'ToMemNo'),''); SELECT @MemName = ISNULL(dbo.FNGetParamValue(@IParam,'MemName'),''); SELECT @MobilePhone = ISNULL(dbo.FNGetParamValue(@IParam,'MobilePhone'),''); SELECT @Gender = ISNULL(dbo.FNGetParamValue(@IParam,'Gender'),-1); SELECT @FromBirthday = ISNULL(dbo.FNGetParamValue(@IParam,'FromBirthday'),''); SELECT @ToBirthday = ISNULL(dbo.FNGetParamValue(@IParam,'ToBirthday'),''); SELECT @FromJoinDate = dbo.FNGetParamValue(@IParam,'FromJoinDate'); SELECT @ToJoinDate = dbo.FNGetParamValue(@IParam,'ToJoinDate'); SELECT @FromPoint = ISNULL( dbo.FNGetParamValue(@IParam,'FromPoint'),0); SELECT @ToPoint = ISNULL(dbo.FNGetParamValue(@IParam,'ToPoint'),0); SELECT @FromLastDate = ISNULL( dbo.FNGetParamValue(@IParam,'FromLastDate'),''); SELECT @ToLastDate = ISNULL(dbo.FNGetParamValue(@IParam,'ToLastDate'),''); SELECT @AfterLastDate = ISNULL(dbo.FNGetParamValue(@IParam,'AfterLastDate'),''); SELECT @FromConsTimes = ISNULL( dbo.FNGetParamValue(@IParam,'FromConsTimes'),NULL); SELECT @ToConsTimes = ISNULL(dbo.FNGetParamValue(@IParam,'ToConsTimes'),NULL); SELECT @FromConsAmt = ISNULL( dbo.FNGetParamValue(@IParam,'FromConsAmt'),NULL); SELECT @ToConsAmt = ISNULL(dbo.FNGetParamValue(@IParam,'ToConsAmt'),NULL); SELECT @FromRchgAmt = ISNULL( dbo.FNGetParamValue(@IParam,'FromRchgAmt'),NULL); SELECT @ToRchgAmt = ISNULL(dbo.FNGetParamValue(@IParam,'ToRchgAmt'),NULL); SELECT @NotComeDay = ISNULL(dbo.FNGetParamValue(@IParam,'NotComeDay'),0); SELECT @FromStatDate = ISNULL(dbo.FNGetParamValue(@IParam,'FromStatDate'),''); SELECT @ToStatDate = ISNULL(dbo.FNGetParamValue(@IParam,'ToStatDate'),''); SELECT @FromCardNo = ISNULL(dbo.FNGetParamValue(@IParam,'FromCardNo'),''); SELECT @ToCardNo = ISNULL(dbo.FNGetParamValue(@IParam,'ToCardNo'),''); SELECT @CardState = ISNULL(dbo.FNGetParamValue(@IParam,'CardState'),0); SELECT @CardTypeNo = ISNULL(dbo.FNGetParamValue(@IParam,'CardTypeNo'),''); SELECT @FromCardCreateDate = ISNULL(dbo.FNGetParamValue(@IParam,'FromCardCreateDate'),NULL); SELECT @ToCardCreateDate = ISNULL(dbo.FNGetParamValue(@IParam,'ToCardCreateDate'),NULL); SELECT @FromCardExpiredDate = ISNULL(dbo.FNGetParamValue(@IParam,'FromCardExpiredDate'),NULL); SELECT @ToCardExpiredDate = ISNULL(dbo.FNGetParamValue(@IParam,'ToCardExpiredDate'),NULL); SELECT @FromRemainTimes = ISNULL(dbo.FNGetParamValue(@IParam,'FromRemainTimes'),0); SELECT @ToRemainTimes = ISNULL(dbo.FNGetParamValue(@IParam,'ToRemainTimes'),0); SELECT @FromBalance = ISNULL(dbo.FNGetParamValue(@IParam,'FromBalance'),0); SELECT @ToBalance = ISNULL(dbo.FNGetParamValue(@IParam,'ToBalance'),0); SELECT @AcctNo = ISNULL(dbo.FNGetParamValue(@IParam,'AcctNo'),''); SELECT @CardExpired = ISNULL(dbo.FNGetParamValue(@IParam,'CardExpired'),0); SELECT @ChargeEmpNo = ISNULL(dbo.FNGetParamValue(@IParam,'ChargeEmpNo'),''); SELECT @FromCourseRemainTimes = ISNULL(dbo.FNGetParamValue(@IParam,'FromCourseRemainTimes'),0); SELECT @ToCourseRemainTimes = ISNULL(dbo.FNGetParamValue(@IParam,'ToCourseRemainTimes'),0); SELECT @CourseNo = ISNULL(dbo.FNGetParamValue(@IParam,'CourseNo'),''); CREATE TABLE #MemCompIds ( FCompId BIGINT ) /* DECLARE @CardCompIds TABLE ( FCompId BIGINT ) */ CREATE TABLE #CardTypeIds ( FCardTypeId BIGINT ) CREATE TABLE #CourseIds ( FCourseId BIGINT ) IF @MemCompNo = ''-- AND @CardCompNo = '' BEGIN RETURN END --会员公司 IF @MemCompNo = 'All' OR @MemCompNo = '' BEGIN INSERT #MemCompIds SELECT FId FROM TCompany END ELSE BEGIN INSERT #MemCompIds SELECT A.FId FROM TCompany AS A WITH(NOLOCK), dbo.FNStrSplit(@MemCompNo) AS B WHERE A.FNo = B.Field END /* --卡公司 IF @CardCompNo = 'All' OR @CardCompNo = '' BEGIN INSERT @CardCompIds SELECT FId FROM TCompany END ELSE BEGIN INSERT @CardCompIds SELECT A.FId FROM TCompany AS A WITH(NOLOCK), dbo.FNStrSplit(@CardCompNo) AS B WHERE A.FNo = B.Field END*/ --储值卡类别 IF @CardTypeNo != '' BEGIN INSERT #CardTypeIds SELECT FId FROM TMemberCardType WITH(NOLOCK) WHERE FNo = @CardTypeNo END IF @CourseNo != '' BEGIN INSERT #CourseIds SELECT FId FROM TCourse WITH(NOLOCK) WHERE FNo IN(SELECT Field FROM dbo.FNStrSplit(@CourseNo)) END --今天日期 DECLARE @Today DATETIME SELECT @Today = CONVERT(varchar(100), GETDATE(), 23) SELECT @ChargeEmpId = 0 IF @ChargeEmpNo != '' BEGIN SELECT @ChargeEmpId = FId FROM TEmployee WHERE FNo = @ChargeEmpNo END --初始化会员表 DECLARE @InsertMember VARCHAR(8000) DECLARE @InsertCard VARCHAR(8000) DECLARE @InsertCourse VARCHAR(8000) DECLARE @MemberWhere VARCHAR(8000) DECLARE @CardWhere VARCHAR(8000) DECLARE @CourseWhere VARCHAR(8000) DECLARE @CardParam NVARCHAR(4000) DECLARE @MemParam NVARCHAR(4000) DECLARE @CourseParam NVARCHAR(4000) SELECT @InsertMember = 'INSERT #Member(FCompId,FCompNo, FMemId,FMemNo,FName,FGender,FMobilePhone,FJoinDate,FBirthday,FBirthdayType,FPoint,FSaleEmpName,FLastDate,FConsTimes,FConsAmt,FRchgAmt)' + ' SELECT A.FCompId,'''' AS FCompNo,FMemId AS FMemId, FMemNo AS FMemNo,A.FName AS FName,A.FGender,A.FMobilePhone,CONVERT(varchar(10),A.FCreateDate,23) AS FJoinDate, ' + ' ISNULL(CONVERT(varchar(10), A.FBirthday, 23),'''') AS FBirthday,A.FBirthdayType,FPoint,'''' AS FSaleEmpName,' + ' CAST('''' AS VARCHAR(10)) AS FLastDate,' + ' CAST(0 AS INT) AS FConsTimes,' + ' CAST(0 AS DECIMAL(18,6)) AS FConsAmt,' + ' CAST(0 AS DECIMAL(18,6)) AS FRchgAmt' + ' FROM TMember AS A WITH(NOLOCK)' SELECT @MemberWhere = ' WHERE 1=1' + ' AND A.FMemId > 99' + ' AND A.FDeleted = 0' + ' AND A.FState = 1 '--转卡' + ' AND (@FromMemNo = '''' OR A.FMemNo BETWEEN @FromMemNo AND @ToMemNo)' + ' AND (@MemName = '''' OR A.FName LIKE ''%'' + @MemName + ''%'')' + ' AND (@MobilePhone = '''' OR A.FMobilePhone = @MobilePhone)' + ' AND (@Gender = -1 OR A.FGender = @Gender)' + ' AND (@FromPoint = 0 OR A.FPoint BETWEEN @FromPoint AND @ToPoint)' + ' AND (@FromBirthday = '''' OR A.FShortBirthday BETWEEN @FromBirthday AND @ToBirthday)' + ' AND (@FromJoinDate IS NULL OR A.FCreateDate BETWEEN @FromJoinDate AND @ToJoinDate)' + ' AND (@ChargeEmpId = 0 OR A.FChargeEmpId = @ChargeEmpId)' SELECT @InsertCard = 'INSERT #MemberCard(FCompId,FCardId,FCardNo,FMemId,FMemNo,FCardTypeId,FCardTypeNo,FCardTypeName,FState,FRemainTimes,FCreateDate,FExpiredDate)' + ' SELECT A.FCompId,A.FCardId AS FCardId,A.FCardNo AS FCardNo,A.FMemId,'''' AS FMemNo,A.FTypeID,'''' AS FCardTypeNo,'''' AS FCardTypeName,A.FState, A.FRemainTimes,' + ' CONVERT(varchar(10), A.FCreateDate,23) AS FCreateDate,' + ' CONVERT(varchar(10), A.FExpiredDate,23) AS FExpiredDate ' + ' FROM TMemberCard AS A WITH(NOLOCK)' SELECT @InsertCourse = 'INSERT #MemberCard(FCompId,FCardId,FCardNo,FMemId,FMemNo,FCardTypeId,FCardTypeNo,FCardTypeName,FState,FRemainTimes,FCreateDate,FExpiredDate,FIsCourse,FItemId)' + ' SELECT A.FCompId,A.FId AS FCardId,'''' AS FCardNo,A.FMemId,'''' AS FMemNo,FCourseId,'''' AS FCardTypeNo,'''' AS FCardTypeName,A.FState, A.FRemainPurTimes + A.FRemainFreeTimes,' + ' CONVERT(varchar(10), A.FPurchaseDate,23) AS FCreateDate,' + ' CONVERT(varchar(10), A.FExpiredDate,23) AS FExpiredDate, ' + ' 1 AS FIsCourse,A.FItemId' + ' FROM TMemberCourse AS A WITH(NOLOCK)' SELECT @CardWhere = 'WHERE 1=1 AND (@CardTypeNo = '''' OR A.FTypeId IN(SELECT FCardTypeId FROM #CardTypeIds)) AND (@FromCardNo = '''' OR A.FCardNo BETWEEN @FromCardNo AND @ToCardNo) AND (@CardState = 0 OR A.FState = @CardState) AND (@FromCardCreateDate IS NULL OR A.FCreateDate BETWEEN @FromCardCreateDate AND @ToCardCreateDate) -- AND (@FromCardExpiredDate IS NULL OR A.FExpiredDate BETWEEN @FromCardExpiredDate AND @ToCardExpiredDate) AND (@CardState = 0 OR A.FState = @CardState) AND (@CardExpired = 0 OR (@CardExpired = 1 AND A.FExpiredDate > @Today /*未过期*/) OR (@CardExpired = -1 AND A.FExpiredDate <= @Today /*过期*/)) AND A.FDeleted = 0 /*没有删除*/ ' SELECT @CourseWhere = 'WHERE 1=1 AND (@CourseNo = '''' OR A.FCourseId IN(SELECT FCourseId FROM #CourseIds)) AND (@CardState = 0 OR A.FState = @CardState) AND (@FromCardCreateDate IS NULL OR A.FPurchaseDate BETWEEN @FromCardCreateDate AND @ToCardCreateDate) -- AND (@FromCardExpiredDate IS NULL OR A.FExpiredDate BETWEEN @FromCardExpiredDate AND @ToCardExpiredDate) AND (@CardExpired = 0 OR (@CardExpired = 1 AND A.FExpiredDate > @Today /*未过期*/) OR (@CardExpired = -1 AND A.FExpiredDate <= @Today /*过期*/)) ' SELECT @MemParam = N'@MemName VARCHAR(30) ,' + ' @MobilePhone VARCHAR(30),' + ' @FromMemNo VARCHAR(30),' + ' @ToMemNo VARCHAR(30),' + ' @FromPoint INT,' + ' @ToPoint INT,' + ' @FromJoinDate DATETIME,' + ' @ToJoinDate DATETIME,' + ' @Gender INT, ' + ' @ChargeEmpId INT, ' + ' @FromBirthday VARCHAR(10),' + ' @ToBirthday VARCHAR(10)' SELECT @CardParam = N'@CardTypeNo VARCHAR(30) ,' + ' @FromCardNo VARCHAR(30),' + ' @ToCardNo VARCHAR(30),' + ' @CardState INT,' + ' @FromCardCreateDate DATETIME,' + ' @ToCardCreateDate DATETIME,' + ' @CardExpired INT, ' + ' @Today VARCHAR(10) ' SELECT @CourseParam = N'@CourseNo VARCHAR(30) ,' + ' @CardState INT,' + ' @FromCardCreateDate DATETIME,' + ' @ToCardCreateDate DATETIME,' + ' @CardExpired INT, ' + ' @Today VARCHAR(10) ' DECLARE @Sql NVARCHAR(4000) IF @CompSource = 2 --以卡的归属公司为准, 先统计卡 BEGIN IF @ShowCardInfo = 1 BEGIN SELECT @Sql = @InsertCard + ' INNER JOIN #MemCompIds AS C ON C.FCompId = A.FCompId ' + @CardWhere PRINT @Sql exec sp_executesql @sql,@CardParam, @CardTypeNo = @CardTypeNo, @FromCardNo = @FromCardNo, @ToCardNo = @ToCardNo, @CardState = @CardState, @ToCardCreateDate = @ToCardCreateDate, @FromCardCreateDate = @FromCardCreateDate, @CardExpired = @CardExpired, @Today = @Today END IF @ShowCourseInfo = 1 BEGIN SELECT @Sql = @InsertCourse + ' INNER JOIN #MemCompIds AS C ON C.FCompId = A.FCompId ' + @CourseWhere PRINT @Sql exec sp_executesql @sql,@CourseParam, @CourseNo = @CourseNo, @CardState = @CardState, @ToCardCreateDate = @ToCardCreateDate, @FromCardCreateDate = @FromCardCreateDate, @CardExpired = @CardExpired, @Today = @Today END --EXEC (@Sql) SELECT @Sql = @InsertMember + @MemberWhere + ' AND EXISTS(SELECT 1 FROM #MemberCard AS C WHERE C.FMemId = A.FMemId) ' PRINT @Sql print @MemParam exec sp_executesql @sql,@MemParam, @MemName = @MemName, @FromMemNo = @FromMemNo, @ToMemNo = @ToMemNo, @Gender = @Gender, @FromJoinDate = @FromJoinDate, @ToJoinDate = @ToJoinDate, @FromPoint = @FromPoint, @ToPoint = @ToPoint, @ChargeEmpId = @ChargeEmpId, @MobilePhone = @MobilePhone, @FromBirthday = @FromBirthday, @ToBirthday = @ToBirthday END ELSE BEGIN SELECT @Sql = @InsertMember + ' INNER JOIN #MemCompIds AS C ON C.FCompId = A.FCompId ' + @MemberWhere PRINT @Sql print @MemParam exec sp_executesql @sql,@MemParam, @MemName = @MemName, @FromMemNo = @FromMemNo, @ToMemNo = @ToMemNo, @Gender = @Gender, @FromJoinDate = @FromJoinDate, @ToJoinDate = @ToJoinDate, @FromPoint = @FromPoint, @ToPoint = @ToPoint, @ChargeEmpId = @ChargeEmpId, @MobilePhone = @MobilePhone, @FromBirthday = @FromBirthday, @ToBirthday = @ToBirthday IF @ShowCardInfo = 1 BEGIN SELECT @Sql = @InsertCard + @CardWhere + ' AND EXISTS(SELECT 1 FROM #Member AS C WHERE C.FMemId = A.FMemId) ' PRINT @Sql exec sp_executesql @sql,@CardParam, @CardTypeNo = @CardTypeNo, @FromCardNo = @FromCardNo, @ToCardNo = @ToCardNo, @CardState = @CardState, @ToCardCreateDate = @ToCardCreateDate, @FromCardCreateDate = @FromCardCreateDate, @CardExpired = @CardExpired, @Today = @Today END IF @ShowCourseInfo = 1 BEGIN SELECT @Sql = @InsertCourse + @CourseWhere + ' AND EXISTS(SELECT 1 FROM #Member AS C WHERE C.FMemId = A.FMemId) ' PRINT @Sql exec sp_executesql @sql,@CourseParam, @CourseNo = @CourseNo, @CardState = @CardState, @ToCardCreateDate = @ToCardCreateDate, @FromCardCreateDate = @FromCardCreateDate, @CardExpired = @CardExpired, @Today = @Today END --EXEC (@Sql) /* INSERT #Member(FCompId,FCompNo, FMemId,FMemNo,FName,FGender,FMobilePhone,FJoinDate,FBirthday,FBirthdayType,FPoint,FSaleEmpName,FLastDate,FConsTimes,FConsAmt,FRchgAmt) SELECT FCompId,'' AS FCompNo,FMemId AS FMemId, FMemNo AS FMemNo,A.FName AS FName,A.FGender,A.FMobilePhone,CONVERT(varchar(10),A.FCreateDate,23) AS FJoinDate, ISNULL(CONVERT(varchar(10), A.FBirthday, 23),'') AS FBirthday,A.FBirthdayType,FPoint,'' AS FSaleEmpName, CAST('' AS VARCHAR(10)) AS FLastDate, CAST(0 AS INT) AS FConsTimes, CAST(0 AS DECIMAL(18,6)) AS FConsAmt, CAST(0 AS DECIMAL(18,6)) AS FRchgAmt FROM TMember AS A WITH(NOLOCK) ,@Companys AS B WHERE A.FCompId = B.CompId AND A.FMemId > 99 AND A.FDeleted = 0 AND A.FState = 1 --转卡 AND (@FromMemNo = '' OR A.FMemNo BETWEEN @FromMemNo AND @ToMemNo) AND (@MemName = '' OR A.FName LIKE '%' + @MemName + '%') AND (@MobilePhone = '' OR A.FMobilePhone = @MobilePhone) AND (@Gender = -1 OR A.FGender = @Gender) AND (@FromPoint = 0 OR A.FPoint BETWEEN @FromPoint AND @ToPoint) AND (@FromBirthday = '' OR A.FShortBirthday BETWEEN @FromBirthday AND @ToBirthday) AND (@FromJoinDate IS NULL OR A.FCreateDate BETWEEN @FromJoinDate AND @ToJoinDate) AND (@ChargeEmpId = 0 OR A.FChargeEmpId = @ChargeEmpId) --初始化卡资料表 INSERT #MemberCard(FCompId,FCardId,FCardNo,FMemId,FMemNo,FCardTypeNo,FCardTypeName,FState,FRemainTimes,FCreateDate,FExpiredDate,FIsCourse) SELECT A.FCompId,A.FCardId AS FCardId,A.FCardNo AS FCardNo,A.FMemId,B.FMemNo,I.FNo AS FCardTypeNo,I.FName AS FCardTypeName,A.FState, A.FRemainTimes, CONVERT(varchar(10), A.FCreateDate,23) AS FCreateDate, CONVERT(varchar(10), A.FExpiredDate,23) AS FExpiredDate, 0 AS FIsCourse -- INTO #MemberCard_ FROM TMemberCard AS A WITH(NOLOCK) LEFT JOIN TMemberCardType AS I WITH(NOLOCK) ON A.FTypeId = I.FId, #Member AS B WHERE A.FMemId = B.FMemId AND (@CardTypeNo = '' OR I.FNo = @CardTypeNo) AND (@FromCardNo = '' OR A.FCardNo BETWEEN @FromCardNo AND @ToCardNo) AND (@CardState = 0 OR A.FState = @CardState) AND (@FromCardCreateDate IS NULL OR A.FCreateDate BETWEEN @FromCardCreateDate AND @ToCardCreateDate) AND (@FromCardExpiredDate IS NULL OR A.FExpiredDate BETWEEN @FromCardExpiredDate AND @ToCardExpiredDate) AND A.FState = 1 AND A.FDeleted = 0 AND A.FState != 3 --转卡 AND A.FExpiredDate >= @Today */ END --交叉删除 --删除卡在会员表中不存在的 DELETE A FROM #MemberCard AS A WHERE NOT EXISTS(SELECT 1 FROM #Member AS B WHERE A.FMemId = B.FMemId) --统计余额 IF @AcctNo != '' AND @FromBalance != 0 AND @ToBalance != 0 BEGIN DECLARE @AcctId BIGINT SELECT @AcctId = FId FROM TPayAccount WITH(NOLOCK) WHERE FNo = @AcctNo IF @AcctId != 0 BEGIN DELETE A FROM #MemberCard AS A,TMemberCardAccount AS B WHERE A.FCardId = B.FCardId AND B.FAcctId = @AcctId AND B.FBalance NOT BETWEEN @FromBalance AND @ToBalance DELETE A FROM #MemberCard AS A WHERE NOT EXISTS(SELECT TOP 1 1 FROM TMemberCardAccount AS B WITH(NOLOCK) WHERE A.FCardId = B.FCardId AND B.FAcctId = @AcctId) END END --如果有卡的条件,就把会员表根据卡表过滤 IF @CompanyForCard = 1 OR @CardTypeNo != '' OR @FromCardNo != '' OR @CardState != 0 OR @FromCardCreateDate != '' OR @FromCardExpiredDate != '' OR @AcctNo != '' BEGIN DELETE A FROM #Member AS A WHERE NOT EXISTS(SELECT 1 FROM #MemberCard AS B WHERE A.FMemId = B.FMemId) END --select @CardTypeNo,@FromCardNo,@ToCardNo,@CardState,@FromCardCreateDate,@FromCardExpiredDate --最后消费日期 UPDATE A SET A.FLastDate = CONVERT(varchar(10), B.Date,23) FROM #Member AS A, ( SELECT A.FMemId,MAX(FTime) AS Date FROM TMemberTransHist AS A WITH(NOLOCK),#Member AS B WHERE A.FMemId = B.FMemId GROUP BY A.FMemId ) AS B WHERE A.FMemid = B.FMemId IF EXISTS(SELECT TOP 1 1 FROM TMemberOldTransHist WITH(NOLOCK)) BEGIN --最后消费日期 UPDATE A SET A.FLastDate = CONVERT(varchar(10), B.Date,23) FROM #Member AS A, ( SELECT A.FMemId,MAX(FTime) AS Date FROM TMemberOldTransHist AS A WITH(NOLOCK),#Member AS B WHERE A.FMemId = B.FMemId AND B.FLastDate = '' GROUP BY A.FMemId ) AS B WHERE A.FMemid = B.FMemId END IF @FromLastDate != '' BEGIN --排除最后消费日期 DELETE #Member WITH(ROWLOCK) WHERE FLastDate NOT BETWEEN @FromLastDate AND @ToLastDate END IF @NotComeDay != 0 BEGIN DECLARE @NoComeDate VARCHAR(10) SELECT @NoComeDate = CONVERT(VARCHAR(10) ,(SELECT DATEADD(d,-@NotComeDay,getdate())),23) DELETE #Member WITH(ROWLOCK) WHERE FLastDate > @NoComeDate END --最后消费日期 IF @AfterLastDate != '' BEGIN DELETE #Member WHERE FLastDate > @AfterLastDate END --消费总次数 UPDATE A SET A.FConsTimes = B.Times FROM #Member AS A, ( SELECT FMemId,SUM(1) AS Times FROM TMemberTransHist WITH(NOLOCK) WHERE FBillType = 'XF' AND (@FromStatDate = '' OR FTime BETWEEN @FromStatDate AND @ToStatDate) GROUP BY FMemId,FTransId ) AS B WHERE A.FMemId = B.FMemId IF EXISTS(SELECT TOP 1 1 FROM TMemberOldTransHist WITH(NOLOCK)) BEGIN UPDATE A SET A.FConsTimes = ISNULL(A.FConsTimes,0) + B.Times FROM #Member AS A, ( SELECT FMemId,SUM(1) AS Times FROM TMemberOldTransHist WITH(NOLOCK) WHERE FBillType = 'DR.XF' AND (@FromStatDate = '' OR FTime BETWEEN @FromStatDate AND @ToStatDate) GROUP BY FMemId,FTransNo ) AS B WHERE A.FMemId = B.FMemId END --排除消费次数 IF @FromConsTimes IS NOT NULL BEGIN DELETE #Member WITH(ROWLOCK) WHERE FConsTimes NOT BETWEEN @FromConsTimes AND @ToConsTimes END --消费和充值总金额 UPDATE A SET A.FConsAmt = B.ConsAmt, A.FRchgAmt = B.RchgAmt FROM #Member AS A, ( SELECT FMemId,SUM(ConsAmt) AS ConsAmt,SUM(RchgAmt) AS RchgAmt FROM (SELECT A.FMemId,SUM(CASE WHEN FBillType = 'XF' THEN FAmount ELSE 0 END) AS ConsAmt, SUM(CASE WHEN FBizType IN('CourseSale','CardRchg','CardSale','CoursePackSale') THEN FAmount ELSE 0 END) AS RchgAmt FROM TMemberTransHist AS A WITH(NOLOCK),#Member AS C WHERE A.FMemId = C.FMemId AND FBillType IN('XF','KK') AND (@FromStatDate = '' OR FTime BETWEEN @FromStatDate AND @ToStatDate) GROUP BY A.FMemId,FBillType,FBizType) AS T GROUP BY FMemId ) AS B WHERE A.FMemId = B.FMemId IF EXISTS(SELECT TOP 1 1 FROM TMemberOldTransHist WITH(NOLOCK)) BEGIN --消费和充值总金额 UPDATE A SET A.FConsAmt = ISNULL(A.FConsAmt,0) + B.ConsAmt, A.FRchgAmt = ISNULL(A.FRchgAmt,0) + B.RchgAmt FROM #Member AS A, ( SELECT FMemId,SUM(ConsAmt) AS ConsAmt,SUM(RchgAmt) AS RchgAmt FROM (SELECT A.FMemId,SUM(CASE WHEN FBillType = 'DR.XF' THEN FAmount ELSE 0 END) AS ConsAmt, SUM(CASE WHEN FBizType IN('DR.CardSale','DR.CardRchg') THEN FAmount ELSE 0 END) AS RchgAmt FROM TMemberOldTransHist AS A WITH(NOLOCK),#Member AS C WHERE A.FMemId = C.FMemId AND FBillType IN('DR.XF','DR.KK') AND (@FromStatDate = '' OR FTime BETWEEN @FromStatDate AND @ToStatDate) GROUP BY A.FMemId,FBillType) AS T GROUP BY FMemId ) AS B WHERE A.FMemId = B.FMemId END --排除消费充值总额 IF (@FromConsAmt IS NOT NULL AND @ToConsAmt IS NOT NULL) BEGIN DELETE #Member WHERE FConsAmt NOT BETWEEN @FromConsAmt AND @ToConsAmt END IF (@FromRchgAmt IS NOT NULL AND @ToRchgAmt IS NOT NULL) BEGIN DELETE #Member WHERE FRchgAmt NOT BETWEEN @FromRchgAmt AND @ToRchgAmt END --最后再清理一次卡 DELETE A FROM #MemberCard AS A WHERE NOT EXISTS(SELECT 1 FROM #Member AS B WHERE A.FMemId = B.FMemId) --卡类别 UPDATE A SET A.FCardTypeName = B.FName FROM #MemberCard AS A,TMemberCardType AS B WHERE A.FCardTypeId = B.FId AND A.FIsCourse = 0 --疗程 UPDATE A SET A.FCardTypeName = B.FName FROM #MemberCard AS A,TCourse AS B WHERE A.FCardTypeId = B.FId AND A.FIsCourse = 1 --项目 UPDATE A SET A.FCardTypeName = B.FName FROM #MemberCard AS A,TItem AS B WHERE A.FItemId = B.FId AND A.FIsCourse = 1 AND A.FCardTypeName = '' --客单价 UPDATE #Member SET FConsPrice = FConsAmt / FConsTimes WHERE FConsTimes > 0 --获取负责员工 UPDATE A SET A.FSaleEmpName = E.FName FROM #Member AS A,TEmployee AS E WITH(NOLOCK) WHERE E.FId = A.FChargeEmpId --获取最喜爱的员工 UPDATE A SET A.FFavoriteEmpName = CASE WHEN A.FFavoriteEmpName IS NULL THEN E.FName ELSE A.FFavoriteEmpName END FROM #Member AS A, ( SELECT TOP 1000000000 A.FMemId,C.FEmpId,SUM(1) AS SUM FROM #Member AS A,TConsumeBill AS T WITH(NOLOCK),TConsumeItemEmployee AS C WITH(NOLOCK) WHERE A.FMemId = T.FMemId AND T.FBillId = C.FBillId AND C.FEmpId != 0 AND C.FDispatchMode = 10001 GROUP BY A.FMemId,C.FEmpId ORDER BY A.FMemId,SUM(1) DESC )AS B ,TEmployee AS E WHERE A.FMemId = B.FMemId AND B.FEmpId = E.FId SELECT FMemNo AS MemNo, A.FName AS Name, C.FAbbr AS MemCompName, FGender AS Gender, FMobilePhone AS MobilePhone, FBirthday AS Birthday, FBirthdayType AS BirthdayType,FJoinDate AS JoinDate, FPoint AS Point, FConsTimes AS ConsTimes, FConsAmt AS ConsAmt, FRchgAmt AS RchgAmt, FLastDate AS LastDate, FConsArrear AS ConsArrear, FCourseArrear AS CourseArrear,FConsPrice AS ConsPrice, FFavoriteEmpName AS FavoriteEmpName,FSaleEmpName AS SaleEmpName FROM #Member AS A ,TCompany AS C WITH(NOLOCK) WHERE A.FCompId = C.FId ORDER BY FMemNo SELECT A.FCardNo AS CardNo, B.FMemNo AS MemNo, C.FAbbr AS CardCompName, A.FCardTypeNo AS CardTypeNo,A.FCardTypeName AS CardTypeName, A.FCreateDate AS CardCreateDate,A.FExpiredDate AS CardExpiredDate,A.FRemainTimes AS CardRemainTimes,A.FState AS CardState FROM #MemberCard AS A LEFT JOIN TCompany AS C WITH(NOLOCK) ON A.FCompId = C.FId,#Member AS B WHERE A.FMemId = B.FMemId ORDER BY FCardNo --获取卡余额表 SELECT B.FCardNo AS CardNo,I.FNo AS AcctNo,I.FName AS AcctName ,A.FBalance AS Balance,A.FArrear AS Arrear FROM TMemberCardAccount AS A WITH(NOLOCK),#MemberCard AS B,TPayAccount AS I WHERE A.FCardId = B.FCardId AND A.FAcctId = I.FId AND ISNULL(B.FIsCourse,0) = 0 ORDER BY B.FCardNo -- select * from TMember --83807855 --15589888082 --SELECT * FROM TMemberTransHist --DECLARE @IParam VARCHAR(8000) --SELECT @IParam = -- ' -- FromMemNo="" -- ToMemNo="888" -- CompanyForCard="1" -- CardTypeNo="A" -- Company="001,002,003,A001" -- MobilePhone="" -- FromBirthday="" -- ToBirthday="1-1209" -- FromLastDate="2012-01-01" -- ToLastDate="2015-05-01" -- ' --EXEC PRptMemberReport @IParam END GO EXEC PRptMemberReport @IParam='Company="001"CompNo="001"CompSource="1"ShowCardInfo="1"ShowCourseInfo="1"FromMemNo="0098"ToMemNo="0098"'