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.
492 lines
15 KiB
492 lines
15 KiB
IF object_id('dbo.PMergeMember','P') IS NOT NULL
|
|
BEGIN
|
|
DROP PROCEDURE dbo.PMergeMember
|
|
END
|
|
GO
|
|
|
|
|
|
CREATE PROCEDURE dbo.PMergeMember
|
|
(
|
|
@SourceMemId BIGINT,
|
|
@TargetMemId BIGINT,
|
|
@TargetCardId BIGINT,
|
|
@CompId BIGINT,
|
|
@UserId BIGINT,
|
|
@Memo VARCHAR(1024)
|
|
)
|
|
AS
|
|
BEGIN
|
|
-- DECLARE @TargetAcctId BIGINT
|
|
-- DECLARE @TargetBalance DECIMAL(18,6)
|
|
|
|
-- SELECT @TargetAcctId = 3
|
|
DECLARE @TargetMemNo VARCHAR(50)
|
|
DECLARE @TargetCardNo VARCHAR(50)
|
|
DECLARE @TargetCardTypeId BIGINT --新卡类别ID
|
|
DECLARE @TargetCardCompId BIGINT --新卡归属公司
|
|
DECLARE @MemState INT
|
|
-- DECLARE @CardState INT
|
|
DECLARE @Point DECIMAL(18,6)
|
|
|
|
SELECT @MemState = FState,
|
|
@Point = FPoint
|
|
FROM TMember WITH(NOLOCK) WHERE FMemId = @SourceMemId
|
|
|
|
IF @@ROWCOUNT = 0
|
|
BEGIN
|
|
RAISERROR('原会员ID不存在',16,1)
|
|
RETURN 50000
|
|
END
|
|
|
|
IF @MemState = 3
|
|
BEGIN
|
|
RAISERROR('原会员已转卡',16,1)
|
|
RETURN 50000
|
|
END
|
|
|
|
|
|
SELECT @MemState = FState,
|
|
@TargetMemNo = FMemNo
|
|
FROM TMember WITH(NOLOCK) WHERE FMemId = @TargetMemId
|
|
IF @@ROWCOUNT = 0
|
|
BEGIN
|
|
RAISERROR('新会员ID不存在',16,1)
|
|
RETURN 50000
|
|
END
|
|
|
|
IF @MemState = 3
|
|
BEGIN
|
|
RAISERROR('新会员已转卡',16,1)
|
|
RETURN 50000
|
|
END
|
|
|
|
|
|
IF @TargetCardId != 0
|
|
BEGIN
|
|
SELECT @TargetCardNo = FCardNo,
|
|
@TargetCardTypeId = FTypeId,
|
|
@TargetCardCompId = FCompId
|
|
FROM TMemberCard WITH(NOLOCK)
|
|
WHERE FCardId = @TargetCardId
|
|
|
|
IF @@ROWCOUNT = 0
|
|
BEGIN
|
|
RAISERROR('储值卡ID不存在',16,1)
|
|
RETURN 50000
|
|
END
|
|
-- SELECT @TargetBalance = FBalance FROM TMemberCardAccount WITH(NOLOCK) WHERE FCardId = @TargetCardId AND FAcctId = @TargetBalance
|
|
END
|
|
ELSE
|
|
BEGIN
|
|
IF EXISTS(SELECT 1 FROM TMemberCard WITH(NOLOCK) WHERE FMemId = @SourceMemId)
|
|
BEGIN
|
|
RAISERROR('必须选择储值卡',16,1)
|
|
RETURN 50000
|
|
END
|
|
END
|
|
|
|
CREATE TABLE #Account
|
|
(
|
|
FAcctId BIGINT,
|
|
FBalance DECIMAL(18,6),
|
|
FArrear DECIMAL(18,6),
|
|
FCreateDate DATETIME,
|
|
FExpiredDate DATETIME,
|
|
FMemo VARCHAR(1024)
|
|
)
|
|
|
|
BEGIN TRAN MergeMember
|
|
|
|
--删除可能重复的
|
|
DELETE TMemberMerge
|
|
WHERE FSourceMemId = @SourceMemId
|
|
AND FTargetMemId = @TargetMemId
|
|
|
|
DELETE TMemberMergeDetail
|
|
WHERE FSourceMemId = @SourceMemId
|
|
AND FTargetMemId = @TargetMemId
|
|
|
|
SELECT FCardId,FCardNo,FTypeId
|
|
INTO #Card
|
|
FROM TMemberCard WITH(NOLOCK)
|
|
WHERE FMemId = @SourceMemId
|
|
|
|
--先转储值卡
|
|
DECLARE @CardId BIGINT
|
|
DECLARE @CardNo VARCHAR(50)
|
|
DECLARE @CardTypeId BIGINT
|
|
DECLARE CardCur CURSOR FOR
|
|
SELECT FCardId,FCardNo,FTypeId FROM #Card
|
|
|
|
OPEN CardCur
|
|
FETCH CardCur INTO @CardId,@CardNo,@CardTypeId
|
|
WHILE @@FETCH_STATUS = 0
|
|
BEGIN
|
|
INSERT #Account(FAcctId,FBalance,FArrear,FCreateDate,FExpiredDate,FMemo)
|
|
SELECT FAcctId,FBalance,FArrear,FCreateDate,FExpiredDate,FMemo
|
|
FROM TMemberCardAccount AS C WITH(NOLOCK)
|
|
WHERE FCardId = @CardId
|
|
AND (FBalance != 0 OR FArrear != 0)
|
|
IF @@ERROR > 0
|
|
BEGIN
|
|
GOTO _ERROR
|
|
END
|
|
|
|
--更新新卡账户
|
|
UPDATE A
|
|
SET A.FBalance = A.FBalance + B.FBalance,
|
|
A.FDeposit = A.FDeposit + B.FBalance,
|
|
A.FArrear = A.FArrear + B.FArrear
|
|
FROM TMemberCardAccount AS A ,#Account AS B
|
|
WHERE A.FCardId = @TargetCardId
|
|
AND A.FAcctId = B.FAcctId
|
|
IF @@ERROR > 0
|
|
BEGIN
|
|
GOTO _ERROR
|
|
END
|
|
|
|
INSERT TMemberCardAccount(FId,FMemId,FCardId,FAcctId,FDeposit,FBalance,FArrear,FCreateDate,FExpiredDate,FMemo)
|
|
SELECT dbo.FNNewId(),@TargetMemId,@TargetCardId,A.FAcctId,A.FBalance,A.FBalance,A.FArrear,A.FCreateDate,A.FExpiredDate,A.FMemo
|
|
FROM #Account AS A
|
|
WHERE NOT EXISTS(SELECT 1 FROM TMemberCardAccount AS B WITH(NOLOCK) WHERE @CardID = B.FCardId AND B.FAcctId = A.FAcctId)
|
|
|
|
IF @@ERROR > 0 GOTO _Error
|
|
----新卡账户历史
|
|
--INSERT INTO TMemberCardAcctHist(FId,FMemId,FCardId,FAcctId,FTime,FCardTypeId,FCompId,FBillType,FBizType,FTransId,FTransNo,FInAmount,FOutAmount,FBalance,FArrear,FRecordTime,FMemo)
|
|
--SELECT dbo.FNNewId(),@TargetMemId,@TargetCardId,A.FAcctId,getdate(),@TargetCardTypeId,@CompId,'HB','ChangeIn',0,'',A.FBalance,0,B.FBalance,A.FArrear,getdate(),'从' + @CardNo + '转入'
|
|
-- FROM #Account AS A,TMemberCardAccount AS B
|
|
-- WHERE A.FAcctId = B.FAcctId
|
|
-- AND B.FCardId = @TargetCardId
|
|
--IF @@ERROR > 0
|
|
--BEGIN
|
|
-- GOTO _ERROR
|
|
--END
|
|
|
|
--更新老卡账户
|
|
UPDATE A
|
|
SET A.FBalance = 0,
|
|
A.FArrear = 0
|
|
FROM TMemberCardAccount AS A
|
|
WHERE A.FCardId = @CardId
|
|
IF @@ERROR > 0
|
|
BEGIN
|
|
GOTO _ERROR
|
|
END
|
|
|
|
|
|
|
|
----老卡账户历史
|
|
--INSERT INTO TMemberCardAcctHist(FId,FMemId,FCardId,FAcctId,FTime,FCardTypeId,FCompId,FBillType,FBizType,FTransId,FTransNo,FInAmount,FOutAmount,FBalance,FArrear,FRecordTime,FMemo)
|
|
--SELECT dbo.FNNewId(),@SourceMemId,@CardId,A.FAcctId,getdate(),@CardTypeId,@CompId,'HB','ChangeOut',0,'',0,A.FBalance,0,A.FArrear,getdate(),'转出到' + @TargetCardNo
|
|
-- FROM #Account AS A
|
|
--IF @@ERROR > 0
|
|
--BEGIN
|
|
-- GOTO _ERROR
|
|
--END
|
|
|
|
|
|
|
|
FETCH CardCur INTO @CardId,@CardNo,@CardTypeId
|
|
END
|
|
CLOSE CardCur
|
|
DEALLOCATE CardCur
|
|
|
|
--积分
|
|
IF ISNULL(@Point,0) != 0
|
|
BEGIN
|
|
UPDATE TMember WITH(ROWLOCK) SET FPoint = FPoint + @Point
|
|
WHERE FMemId = @TargetMemId
|
|
IF @@ERROR > 0 GOTO _Error
|
|
END
|
|
|
|
--积分历史
|
|
INSERT TMemberMergeDetail(FId,FSourceMemId,FSourceCardId,FTargetMemId,FDetailType,FDetailId)
|
|
SELECT dbo.FNNewId(),@SourceMemId,FCardId,@TargetMemId,'PointHist',FId
|
|
FROM TMemberPointHist WITH(NOLOCK)
|
|
WHERE FMemId = @SourceMemId
|
|
IF @@ERROR > 0 GOTO _Error
|
|
|
|
UPDATE TMemberPointHist
|
|
SET FMemId = @TargetMemId,
|
|
FCardId = @TargetCardId
|
|
WHERE FMemId = @SourceMemId
|
|
IF @@ERROR > 0 GOTO _Error
|
|
|
|
--疗程
|
|
INSERT TMemberMergeDetail(FId,FSourceMemId,FSourceCardId,FTargetMemId,FDetailType,FDetailId)
|
|
SELECT dbo.FNNewId(),@SourceMemId,0,@TargetMemId,'Course',FId
|
|
FROM TMemberCourse WITH(NOLOCK)
|
|
WHERE FMemId = @SourceMemId
|
|
IF @@ERROR > 0 GOTO _Error
|
|
|
|
UPDATE A
|
|
SET A.FMemId = @TargetMemId
|
|
FROM TMemberCourse AS A
|
|
WHERE A.FMemId = @SourceMemId
|
|
IF @@ERROR > 0 GOTO _Error
|
|
|
|
--记录疗程历史
|
|
INSERT TMemberMergeDetail(FId,FSourceMemId,FSourceCardId,FTargetMemId,FDetailType,FDetailId)
|
|
SELECT dbo.FNNewId(),@SourceMemId,0,@TargetMemId,'CourseHist',FId
|
|
FROM TMemberCourseHist WITH(NOLOCK)
|
|
WHERE FMemId = @SourceMemId
|
|
IF @@ERROR > 0 GOTO _Error
|
|
|
|
UPDATE A
|
|
SET A.FMemId = @TargetMemId
|
|
FROM TMemberCourseHist AS A
|
|
WHERE A.FMemId = @SourceMemId
|
|
IF @@ERROR > 0 GOTO _Error
|
|
|
|
--套餐
|
|
INSERT TMemberMergeDetail(FId,FSourceMemId,FSourceCardId,FTargetMemId,FDetailType,FDetailId)
|
|
SELECT dbo.FNNewId(),@SourceMemId,0,@TargetMemId,'CoursePack',FId
|
|
FROM TMemberCourseHist WITH(NOLOCK)
|
|
WHERE FMemId = @SourceMemId
|
|
IF @@ERROR > 0 GOTO _Error
|
|
|
|
UPDATE A
|
|
SET A.FMemId = @TargetMemId
|
|
FROM TMemberCoursePack AS A
|
|
WHERE A.FMemId = @SourceMemId
|
|
IF @@ERROR > 0 GOTO _Error
|
|
|
|
|
|
--疗程产品
|
|
INSERT TMemberMergeDetail(FId,FSourceMemId,FSourceCardId,FTargetMemId,FDetailType,FDetailId)
|
|
SELECT dbo.FNNewId(),@SourceMemId,0,@TargetMemId,'CourseGoods',FId
|
|
FROM TMemberCourseHist WITH(NOLOCK)
|
|
WHERE FMemId = @SourceMemId
|
|
IF @@ERROR > 0 GOTO _Error
|
|
|
|
UPDATE A
|
|
SET A.FMemId = @TargetMemId
|
|
FROM TMemberCourseGoods AS A
|
|
WHERE A.FMemId = @SourceMemId
|
|
IF @@ERROR > 0 GOTO _Error
|
|
|
|
|
|
--记录账户历史
|
|
INSERT TMemberMergeDetail(FId,FSourceMemId,FSourceCardId,FTargetMemId,FDetailType,FDetailId)
|
|
SELECT dbo.FNNewId(),@SourceMemId,FCardId,@TargetMemId,'CardAcctHist',FId
|
|
FROM TMemberCardAcctHist WITH(NOLOCK)
|
|
WHERE FMemId = @SourceMemId
|
|
IF @@ERROR > 0 GOTO _Error
|
|
|
|
UPDATE TMemberCardAcctHist
|
|
SET FCardId = @TargetCardId,
|
|
FMemId = @TargetMemId
|
|
WHERE FMemId = @SourceMemId
|
|
IF @@ERROR > 0 GOTO _Error
|
|
|
|
|
|
--交易历史
|
|
INSERT TMemberMergeDetail(FId,FSourceMemId,FSourceCardId,FTargetMemId,FDetailType,FDetailId)
|
|
SELECT dbo.FNNewId(),@SourceMemId,FCardId,@TargetMemId,'TransHist',FId
|
|
FROM TMemberTransHist WITH(NOLOCK)
|
|
WHERE FMemId = @SourceMemId
|
|
IF @@ERROR > 0 GOTO _Error
|
|
|
|
UPDATE TMemberTransHist
|
|
SET FCardId = @TargetCardId,
|
|
FMemId = @TargetMemId
|
|
WHERE FMemId = @SourceMemId
|
|
IF @@ERROR > 0 GOTO _Error
|
|
|
|
----交易历史支付方式
|
|
--INSERT TMemberMergeDetail(FId,FSourceMemId,FSourceCardId,FTargetMemId,FDetailType,FDetailId)
|
|
--SELECT dbo.FNNewId(),@SourceMemId,FCardId,@TargetMemId,'TransHistPayment',FId
|
|
-- FROM TMemberTransHistPayment WITH(NOLOCK)
|
|
-- WHERE FMemId = @SourceMemId
|
|
|
|
--UPDATE TMemberTransHistPayment
|
|
-- SET FCardId = @TargetCardId,
|
|
-- FMemId = @TargetMemId
|
|
-- WHERE FMemId = @SourceMemId
|
|
|
|
|
|
--老系统账户历史
|
|
INSERT TMemberMergeDetail(FId,FSourceMemId,FSourceCardId,FTargetMemId,FDetailType,FDetailId)
|
|
SELECT dbo.FNNewId(),@SourceMemId,FCardId,@TargetMemId,'CardOldAcctHist',FId
|
|
FROM TMemberCardOldAcctHist WITH(NOLOCK)
|
|
WHERE FMemId = @SourceMemId
|
|
IF @@ERROR > 0 GOTO _Error
|
|
|
|
UPDATE TMemberCardOldAcctHist
|
|
SET FCardId = @TargetCardId,
|
|
FMemId = @TargetMemId
|
|
WHERE FMemId = @SourceMemId
|
|
IF @@ERROR > 0 GOTO _Error
|
|
|
|
|
|
--老系统交易历史
|
|
INSERT TMemberMergeDetail(FId,FSourceMemId,FSourceCardId,FTargetMemId,FDetailType,FDetailId)
|
|
SELECT dbo.FNNewId(),@SourceMemId,FCardId,@TargetMemId,'OldTransHist',FId
|
|
FROM TMemberOldTransHist WITH(NOLOCK)
|
|
WHERE FMemId = @SourceMemId
|
|
IF @@ERROR > 0 GOTO _Error
|
|
|
|
UPDATE TMemberOldTransHist
|
|
SET FCardId = @TargetCardId,
|
|
FMemId = @TargetMemId
|
|
WHERE FMemId = @SourceMemId
|
|
IF @@ERROR > 0 GOTO _Error
|
|
|
|
--欠款
|
|
INSERT TMemberMergeDetail(FId,FSourceMemId,FSourceCardId,FTargetMemId,FDetailType,FDetailId)
|
|
SELECT dbo.FNNewId(),@SourceMemId,FCardId,@TargetMemId,'Arrear',FId
|
|
FROM TMemberTransHist WITH(NOLOCK)
|
|
WHERE FMemId = @SourceMemId
|
|
IF @@ERROR > 0 GOTO _Error
|
|
|
|
UPDATE TMemberArrear
|
|
SET FCardId = @TargetCardId,
|
|
FMemId = @TargetMemId
|
|
WHERE FMemId = @SourceMemId
|
|
IF @@ERROR > 0 GOTO _Error
|
|
|
|
--还款
|
|
INSERT TMemberMergeDetail(FId,FSourceMemId,FSourceCardId,FTargetMemId,FDetailType,FDetailId)
|
|
SELECT dbo.FNNewId(),@SourceMemId,0,@TargetMemId,'Repay',FId
|
|
FROM TMemberRepay WITH(NOLOCK)
|
|
WHERE FMemId = @SourceMemId
|
|
IF @@ERROR > 0 GOTO _Error
|
|
|
|
UPDATE TMemberRepay
|
|
SET FMemId = @TargetMemId
|
|
WHERE FMemId = @SourceMemId
|
|
IF @@ERROR > 0 GOTO _Error
|
|
|
|
|
|
----欠款员工
|
|
--INSERT TMemberMergeDetail(FId,FSourceMemId,FSourceCardId,FTargetMemId,FDetailType,FDetailId)
|
|
--SELECT dbo.FNNewId(),@SourceMemId,0,@TargetMemId,'ArrearEmployee',FId
|
|
-- FROM TMemberArrearEmployee WITH(NOLOCK)
|
|
-- WHERE FMemId = @SourceMemId
|
|
|
|
--UPDATE TMemberArrearEmployee
|
|
-- SET FMemId = @TargetMemId
|
|
-- WHERE FMemId = @SourceMemId
|
|
|
|
--消费单据
|
|
UPDATE A
|
|
SET A.FMemId = @TargetMemId,
|
|
A.FMemNo = @TargetMemNo,
|
|
A.FCardId = CASE WHEN A.FCardId != 0 THEN @TargetCardId ELSE A.FCardId END,
|
|
A.FCardNo = CASE WHEN A.FCardId != 0 THEN @TargetCardNo ELSE A.FCardNo END
|
|
FROM TConsumeBill AS A
|
|
WHERE A.FMemId = @SourceMemId
|
|
IF @@ERROR > 0 GOTO _Error
|
|
|
|
--开单
|
|
UPDATE A
|
|
SET A.FMemId = @TargetMemId,
|
|
A.FMemNo = @TargetMemNo,
|
|
A.FCardId = CASE WHEN A.FCardId != 0 THEN @TargetCardId ELSE A.FCardId END,
|
|
A.FCardNo = CASE WHEN A.FCardId != 0 THEN @TargetCardNo ELSE A.FCardNo END
|
|
FROM TOrderBill AS A
|
|
WHERE A.FMemId = @SourceMemId
|
|
IF @@ERROR > 0 GOTO _Error
|
|
|
|
--预约
|
|
UPDATE A
|
|
SET A.FMemId = @TargetMemId,
|
|
A.FMemNo = @TargetMemNo
|
|
FROM TBookingRequest AS A
|
|
WHERE A.FMemId = @SourceMemId
|
|
IF @@ERROR > 0 GOTO _Error
|
|
|
|
|
|
|
|
--开卡单
|
|
UPDATE A
|
|
SET A.FMemId = @TargetMemId,
|
|
A.FMemNo = @TargetMemNo,
|
|
A.FPayCardId = CASE WHEN A.FPayCardId != 0 THEN @TargetCardId ELSE A.FPayCardId END,
|
|
A.FPayCardNo = CASE WHEN A.FPayCardId != 0 THEN @TargetCardNo ELSE A.FPayCardNo END
|
|
FROM TMemberSaleBill AS A
|
|
WHERE A.FMemId = @SourceMemId
|
|
IF @@ERROR > 0 GOTO _Error
|
|
|
|
UPDATE A
|
|
SET A.FCardId = @TargetCardId,
|
|
A.FCardNo = @TargetCardNo,
|
|
A.FCardFaceNo = @TargetCardNo
|
|
FROM TMemberSaleCard AS A WITH(ROWLOCK),#Card AS B
|
|
WHERE A.FCardId = B.FCardId
|
|
IF @@ERROR > 0 GOTO _Error
|
|
|
|
UPDATE A
|
|
SET A.FCardId = @TargetCardId,
|
|
A.FCardNo = @TargetCardNo
|
|
FROM TMemberSaleExchange AS A WITH(ROWLOCK),#Card AS B
|
|
WHERE A.FCardId = B.FCardId
|
|
IF @@ERROR > 0 GOTO _Error
|
|
|
|
|
|
--重新计算账户历史余额
|
|
EXEC PRecalcCardAccHistBalance @TargetCardId
|
|
IF @@ERROR > 0 GOTO _Error
|
|
|
|
UPDATE A
|
|
SET A.FState = 3
|
|
FROM TMember AS A
|
|
WHERE A.FMemId = @SourceMemId
|
|
IF @@ERROR > 0 GOTO _ERROR
|
|
|
|
UPDATE A
|
|
SET A.FState = 3
|
|
FROM TMemberCard AS A
|
|
WHERE A.FMemId = @SourceMemId
|
|
IF @@ERROR > 0 GOTO _ERROR
|
|
|
|
--会员合并记录
|
|
INSERT TMemberMerge(FId,FSourceMemId,FTargetMemId,FTargetCardId,FCreatorId,FCreateTime,FMemo,FAutoGen)
|
|
SELECT dbo.FNNewId(),@SourceMemId,@TargetMemId,@TargetCardId,@UserId,GETDATE(),@Memo,0
|
|
IF @@ERROR > 0 GOTO _ERROR
|
|
|
|
|
|
--把相关的也导进来
|
|
INSERT TMemberMerge(FId,FSourceMemId,FTargetMemId,FTargetCardId,FCreatorId,FCreateTime,FMemo,FAutoGen)
|
|
SELECT dbo.FNNewId(),FSourceMemId,@TargetMemId,@TargetCardId,@UserId,GETDATE(),@Memo,1
|
|
FROM TMemberMerge
|
|
WHERE FTargetMemId = @SourceMemId
|
|
|
|
IF @@ERROR > 0 GOTO _ERROR
|
|
|
|
--把相关的也导进来
|
|
INSERT TMemberMergeDetail(FId,FSourceMemId,FSourceCardId,FTargetMemId,FDetailType,FDetailId)
|
|
SELECT dbo.FNNewId(),FSourceMemId,FSourceCardId,@TargetMemId,FDetailType,FDetailId
|
|
FROM TMemberMergeDetail
|
|
WHERE FTargetMemId = @SourceMemId
|
|
|
|
IF @@ERROR > 0 GOTO _Error
|
|
GOTO _OK
|
|
|
|
|
|
_ERROR:
|
|
ROLLBACK TRAN MergeMember
|
|
RETURN -1
|
|
|
|
_OK:
|
|
COMMIT TRAN MergeMember
|
|
EXEC PSetEmpPerfCacheExpired 1
|
|
RETURN 0
|
|
|
|
END
|
|
GO
|
|
|
|
--SELECT * FROM TMemberMerge
|
|
|
|
--DELETE
|
|
--TMemberMerge
|
|
|
|
--SELECT * FROM TMemberCard WHERE FCardNO = 'ZK001'
|
|
|
|
--DELETE TMemberCourse WHERE FMemId = 5452082460835465645
|
|
|
|
--DELETE TMemberCardAcctHist WHERE FCardId IN (SELECT FCardId FROM TMemberCard WHERE FCardNo IN('ZK001', 'ZK002','ZK003'))
|
|
--DELETE TMemberTransHist WHERE FCardId IN (SELECT FCardId FROM TMemberCard WHERE FCardNo IN('ZK001', 'ZK002','ZK003'))
|
|
|
|
--DELETE TMember
|
|
--DELETE TMemberCourseHist
|
|
|