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.
 
 
 

638 lines
31 KiB

USE [FastMoneyPro_Remit]
GO
/****** Object: StoredProcedure [dbo].[proc_RewardPointOperation] Script Date: 9/27/2019 1:30:14 PM ******/
SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO
CREATE OR ALTER PROCEDURE [dbo].[proc_RewardPointOperation]
@flag VARCHAR(30),
@orderId VARCHAR(50) = null,
@customerId VARCHAR(30) = null,
@productCode VARCHAR(50) = null,
@branchCode INT = null,
@recvType INT = null,
@recvAddress VARCHAR(200) = null,
@recvZipCode VARCHAR(20) = null,
@recvPhoneNumber VARCHAR(30) = null,
@recvName VARCHAR(30) = null,
@startDate DateTime = null,
@endDate DateTime = null,
@createdBy VARCHAR(20) = null,
@modifiedBy VARCHAR(20) = null,
@orderType VARCHAR(3) = null,
@sortBy VARCHAR(50) = null,
@sortOrder VARCHAR(5) = null,
@table VARCHAR(max)=null,
@sql_filter VARCHAR(max) = null,
@searchCriteria VARCHAR(30) = null,
@searchValue VARCHAR(50) = null,
@select_field_list VARCHAR(max) = null,
@extra_field_list VARCHAR(max) = null,
@pageSize int = null,
@pageNumber int = NULL,
@user VARCHAR(100) = null,
@email VARCHAR(100) = null,
@schemeId INT = null
AS
SET NOCOUNT ON
-------------------------------- 구매할 수 있는 제품 리스트
IF @flag='productlist'
BEGIN
SELECT PL.productCode,PL.productName,PL.pointPrice,PL.deliveryYN, PL.productImgPath, PL.buyType, PL.couponType
FROM ProductList PL(NOLOCK)
ORDER BY PL.productCode ASC
END
--------------------------------END 구매할 수 있는 제품 리스트
-------------------------------- 제품 구매 요청
IF @flag='buyproduct'
BEGIN
DECLARE
@pointPrice money,
@bounsPoint money,
@productname VARCHAR(20),
@mobilenumber VARCHAR(20)
-- 수령 타입 체크
IF @recvType != '1'
BEGIN
IF @recvType != '2'
BEGIN
IF @recvType != '3'
BEGIN
EXEC proc_errorHandler 1, 'Wrong recv Type.', NULL
RETURN
END
END
END
--주문 타입 체크
IF @orderType != '1'
BEGIN
EXEC proc_errorHandler 1, 'Wrong order Type .', NULL
RETURN
END
-- 회원 정보가 없으면 오류 출력
IF NOT EXISTS(
SELECT '1' FROM customerMaster(NOLOCK) CM
WHERE @email = CM.email
)
BEGIN
EXEC proc_errorHandler 1, 'No User Information.', NULL
RETURN
END
-- 지점에서 수령 시 값 체크
IF @recvType = '2' -- 수령(1:택배, 2:지점)
BEGIN
IF ISNULL(@branchCode,'') = ''
BEGIN
EXEC proc_errorHandler 1, 'input branchCode.', NULL
RETURN
END
-- 브랜치 정보를 못 찾았을 때,
IF NOT EXISTS(
SELECT '1'
FROM agentMaster(NOLOCK) AM
WHERE AM.agentId = @branchCode
)
BEGIN
EXEC proc_errorHandler 1, 'No Branch Information.', NULL
RETURN
END
END
--택배 수령 시 값 체크
IF @recvType = '1'
BEGIN
IF ISNULL(@recvAddress,'') = ''
BEGIN
EXEC proc_errorHandler 1, 'input recv Address.', NULL
RETURN
END
IF ISNULL(@recvZipCode,'') = ''
BEGIN
EXEC proc_errorHandler 1, 'input recv ZipCode.', NULL
RETURN
END
IF ISNULL(@recvPhoneNumber,'') = ''
BEGIN
EXEC proc_errorHandler 1, 'input recv PhoneNumber.', NULL
RETURN
END
IF ISNULL(@recvName,'') = ''
BEGIN
EXEC proc_errorHandler 1, 'input recv Name.', NULL
RETURN
END
END
IF NOT EXISTS
(SELECT '1'
FROM ProductList(nolock) PL
WHERE @productCode = PL.productCode
)
BEGIN
EXEC proc_errorHandler 1, 'No Product.', NULL
RETURN
END
SELECT @pointPrice = PL.pointPrice,
@productname = productName
FROM ProductList(nolock) PL
WHERE @productCode = PL.productCode
--- 제품 가격이 없으면 오류 출력
IF ISNULL(@pointPrice, '') = ''
BEGIN
EXEC proc_errorHandler 1, 'No Product Price.', NULL
RETURN
END
--- 제품 이름이 없으면 오류 출력
IF ISNULL(@productname, '') = ''
BEGIN
EXEC proc_errorHandler 1, 'No Product Name.', NULL
RETURN
END
-- 회원이 제품 구매 가격보다 큰 포인트를 가지고 있는지
SELECT @customerId = customerId,@bounsPoint = bonusPoint
FROM customerMaster(NOLOCK)
WHERE @email = email AND bonusPoint >= @pointPrice
-- 없다면 오류 출력
IF ISNULL(@bounsPoint,'') = ''
BEGIN
EXEC proc_errorHandler 1, 'Point is not enough to purchase.', NULL
RETURN
END
BEGIN TRY
BEGIN TRAN
-- 회원 정보에 포인트를 뺀 가격을 업데이트 한다.
UPDATE customerMaster
SET bonusPoint = (bonusPoint - @pointPrice)
WHERE @email = email
--- 주문 정보 입력
INSERT INTO ProductOrder
(
orderId,
customerId,
productCode,
usePoint,
orderType,
recvType,
branchCode,
recvAddress,
recvZipCode,
recvPhoneNumber,
recvName,
createdBy,
createdDate,
modifiedBy,
modifiedDate,
orderStatus,
recvDate,
recvBy
)
SELECT
@orderId,
@customerId,
@productCode,
@pointPrice,
@orderType,
@recvType,
@branchCode,
@recvAddress,
@recvZipCode,
@recvPhoneNumber,
@recvName,
@email,
GETDATE(),
null,
null,
'1', --(1:주문, 9:취소)
null,
null
-- 주문 내역에 대하여 로그를 기록한다
INSERT INTO PointHistory
(
customerId,
availablePoint,
tranId,
pointType,
point,
createdBy,
createdDate
)
SELECT
CM.customerId,
CM.bonusPoint,
@orderId,
'9', -- (1: 송금횟수로 적립, 2: 송금액으로 적립, 9:포인트 사용, 11: 송금횟수 적립취소, 21:송금액 적립취소, 91:포인트 사용취소)
@pointPrice,
CM.email,
GETDATE()
FROM customerMaster(NOLOCK) CM
WHERE @email = CM.email
EXEC proc_errorHandler 0, 'The Order is Success.', NULL
SELECT @mobilenumber = mobile
FROM customerMaster(NOLOCK)
WHERE customerId = @customerId
SELECT
agentEmail1,
agentName,
@productname AS productname,
@mobilenumber AS mobile
FROM agentMaster(NOLOCK)
WHERE agentId = @branchCode
SELECT buyType AS productType, schemeId AS CouponId FROM ProductList WHERE productCode = @productCode
COMMIT TRAN
END TRY
BEGIN CATCH
IF @@TRANCOUNT > 0
ROLLBACK TRANSACTION;
PRINT ERROR_MESSAGE()
END CATCH
RETURN
END
--------------------------------END 제품 구매 요청
-------------------------------- 주문 내역
--orderType (1:주문, 9:취소)
IF @flag='orderedlist'
BEGIN
-- 회원 정보가 없으면 오류 출력
IF NOT EXISTS(
SELECT '1' FROM customerMaster(NOLOCK) CM
WHERE @email = CM.email
)
BEGIN
EXEC proc_errorHandler 1, 'No User Information.', NULL
RETURN
END
SELECT @customerId = customerId FROM customerMaster(NOLOCK) CM
WHERE @email = CM.email
EXEC proc_errorHandler 0, 'Success', NULL
SELECT
PO.orderId,
PO.productCode,
PL.productName,
PO.usePoint,
PO.orderType,
PO.recvType,
PO.branchCode,
AM.agentName,
PO.recvAddress,
PO.recvZipCode,
PO.recvPhoneNumber,
PO.recvName,
PO.orderStatus,
PO.createdDate,
PO.modifiedDate,
PO.recvDate
FROM ProductOrder PO(NOLOCK)
LEFT JOIN ProductList PL
ON PO.productCode = PL.productCode
LEFT JOIN agentMaster AM
ON PO.branchCode = AM.agentId
WHERE
@customerId = PO.customerId
AND
@startDate <= CONVERT(date, PO.createdDate)
AND
@endDate >= CONVERT(date, PO.createdDate)
ORDER BY PO.createdDate DESC
RETURN
END
--------------------------------END 주문 내역
-------------------------------- 물건 수령
----orderStatus (1:주문완료, 2:발송완료, 3:수령완료, 9:취소처리)
IF @flag='receiptorder'
BEGIN
IF EXISTS(
SELECT 'X'
FROM ProductOrder(NOLOCK)
WHERE @orderId = orderId
)
BEGIN
--select * from ProductOrder where orderId = '20190522531018896'
--select * from PointHistory where tranId = '20190522531018896'
BEGIN TRY
BEGIN TRAN
UPDATE ProductOrder
SET orderType = '1', -- 1:주문, 9:취소
orderStatus = '3',
recvBy = @user,
recvDate = GETDATE()
WHERE @orderId = orderId
---- 물건 수령에 대하여 로그를 기록한다
--INSERT INTO PointHistory
--(
--customerId,
--availablePoint,
--tranId,
--pointType,
--point,
--createdBy,
--createdDate
--)
--SELECT
--CM.customerId,
--CM.bonusPoint,
--@orderId,
--'9', -- (1: 송금횟수로 적립, 2: 송금액으로 적립, 9:포인트 사용, 11: 송금횟수 적립취소, 21:송금액 적립취소, 91:포인트 사용취소)
--@pointPrice,
--@createdBy,
--GETDATE()
--FROM customerMaster(NOLOCK) CM
--WHERE @email = CM.email -- 수정해야함
EXEC proc_errorHandler 0, 'Receipt Success.', NULL
COMMIT
RETURN
END TRY
BEGIN CATCH
IF @@TRANCOUNT > 0
ROLLBACK TRANSACTION;
PRINT ERROR_MESSAGE()
END CATCH
END
-- 주문 정보를 못 찾았을 때
BEGIN
EXEC proc_errorHandler 1, 'CustomerId or OrderId is wrong.', NULL
RETURN
END
END
--------------------------------END 물건 수령
-------------------------------- 주문 취소
IF @flag='canceluse'
BEGIN
DECLARE @V_RET_POINT MONEY, @availablePoint MONEY
BEGIN TRY
BEGIN TRAN
IF EXISTS(SELECT '1' FROM ProductOrder WHERE orderId = @orderId )
BEGIN
--쿠폰일때 취소를 하지못한다.
SELECT @recvType = recvType FROM ProductOrder WHERE orderId = @orderId
IF @recvType = '3'
BEGIN
EXEC proc_errorHandler 1, 'It is an item that can not be cancelled.', NULL
END
ELSE
BEGIN
----CANCEL Product in Order Table
UPDATE ProductOrder
SET orderType = '9',
orderStatus = '9', --orderStatus (1:주문완료, 2:발송완료, 3:수령완료, 9:취소처리)
modifiedBy = @user,
modifiedDate = GETDATE()
WHERE orderId = @orderId
--------------------------------------
----Find use Point in PointHistory Table
SELECT @customerId = customerId, @V_RET_POINT = point
FROM PointHistory
WHERE tranId = @orderId
--------------------------------------
SELECT @availablePoint = bonusPoint, @email = email
FROM customerMaster
WHERE customerId = @customerId
------ recover bonusPoint
UPDATE
customerMaster
SET bonusPoint = @availablePoint + @V_RET_POINT
WHERE customerId =@customerId
--------------------------------------
INSERT INTO
dbo.PointHistory(
customerId,
availablePoint,
tranId,
pointType,
point,
createdBy,
createdDate
)
SELECT
@customerId,
@availablePoint + @V_RET_POINT,
@orderId,
'91',
@V_RET_POINT,
@user,
GETDATE()
EXEC proc_errorHandler 0, 'The Order Cancel is Success.', NULL
END
END
COMMIT
RETURN
END TRY
BEGIN CATCH
IF @@TRANCOUNT > 0
ROLLBACK TRANSACTION;
PRINT ERROR_MESSAGE()
END CATCH
END
--------------------------------END 주문 취소
--------------------------------검색 필드 -- 첫번째 필드가 @searchCriteria 와 일치하면 된다.
IF @flag='searchCriteria'
BEGIN
SELECT '' value, 'Select' [text] UNION ALL
SELECT 'orderId', 'Order ID' UNION ALL
SELECT 'email', 'E-Mail'
RETURN
END
If @flag='Status'
begin
SELECT '' [value], 'Select' [text] UNION ALL
SELECT '1' , 'Order' UNION ALL
SELECT '3' , 'Receipt' UNION ALL
SELECT '9' , 'Cancel'
return
END
If @flag='branch'
begin
SELECT '' [value], 'Select' [text] UNION ALL
select cast(agentid as varchar(10)),AGENTNAME from agentmaster(nolock) where parentid=1008
return
END
-------------------------------------------
IF @flag='grid'
BEGIN
IF @sortBy IS NULL
SET @sortBy = 'orderid'
IF @sortOrder IS NULL
SET @sortOrder = 'DESC'
--------------
-- (1:주문완료, 2:발송완료, 3:수령완료, 9:취소처리)
--SELECT rowid,
--orderId AS orderid,
--customerId,
--productCode AS productname,
--usePoint,
--orderStatus,
--(CASE
--WHEN orderStatus = '1'
--THEN '&nbsp;<a class=\"btn btn-xs btn-primary\" title=\"Edit\" href=\"RewardPointManagement.aspx?orderid=@orderid&method=cancel\"><i class=\"fa fa-pencil\"></i></a>&nbsp;<a class=\"btn btn-xs btn-success\" title=\"Approve\" href=\"RewardPointManagement.aspx?orderid=@orderid&method=receipt\"><i class=\"fa fa-check\"></i></a>'
--WHEN orderStatus = '3'
--THEN '&nbsp;<a class=\"btn btn-xs btn-primary\" title=\"Edit\" href=\"RewardPointManagement.aspx?orderid=@orderid&method=cancel\"><i class=\"fa fa-pencil\"></i></a>&nbsp;'
--WHEN orderStatus = '9'
--THEN ''
--ELSE ''
-- END) AS set
--FROM dbo.ProductOrder
--where 1=1
-------
SET @table = '(SELECT PO.rowid,
orderId AS orderid,
orderStatus,
CM.email,
PL.productName AS productname,
CONVERT(INT, usePoint) AS usePoint,
(CASE
WHEN orderStatus = ''1''
THEN ''Order''
WHEN orderStatus = ''3''
THEN ''Receipt''
WHEN orderStatus = ''9''
THEN ''Cancel''
ELSE ''''
END) AS orderStat
,
(CASE
WHEN orderStatus = ''1''
THEN ''&nbsp;<a class="btn btn-xs btn-primary" title="cancel" href="RewardPointManagement.aspx?orderid=@orderid&method=cancel"><i class="fa fa-remove"></i></a>&nbsp;<a class="btn btn-xs btn-success" title="receipt" href="RewardPointManagement.aspx?orderid=@orderid&method=receipt"><i class="fa fa-check"></i></a>''
WHEN orderStatus = ''3''
THEN ''''
WHEN orderStatus = ''9''
THEN ''''
ELSE ''''
END) AS tagBtn
,po.createdDate as orderdate
,AM.AGENTNAME AS RequestBranch
,AM.AGENTID
FROM dbo.ProductOrder PO
JOIN dbo.customerMaster CM
ON PO.customerId = CM.customerId
JOIN dbo.ProductList PL
ON PL.productCode = PO.productCode
INNER JOIN AGENTMASTER AM
ON AM.AGENTID=PO.BRANCHCODE
where AM.parentid=1008
) x'
-------
--- AS 값이 code의 GridColumn 의 첫번째 파라미터와 일치하면 된다.
--SET @table = '(SELECT rowid,orderId AS orderid,customerId,productCode AS productname,usePoint,orderStatus FROM dbo.ProductOrder
-- where 1=1
-- ) x'
PRINT @table
SET @sql_filter = ''
IF ISNULL(@searchCriteria,'')<>'' AND ISNULL(@searchValue,'')<>''
BEGIN
IF @searchCriteria='orderId'
SET @sql_Filter=@sql_Filter + ' AND orderId like ''' +@searchValue+'%'''
ELSE IF @searchCriteria='email'
SET @sql_Filter=@sql_Filter + ' AND email like ''' +@searchValue+'%'''
END
if @branchCode is not null
SET @sql_Filter=@sql_Filter + 'and AGENTID =' +@branchCode
if @orderType is not null
SET @sql_Filter=@sql_Filter + 'and orderStatus =' + @orderType
--- code의 GridColumn 의 첫번째 파라미터와 일치하면 된다.
SET @select_field_list ='rowid,RequestBranch,orderid,email,productname,usePoint,orderStatus,orderStat,orderdate,tagBtn'
EXEC dbo.proc_paging
@table
,@sql_filter
,@select_field_list
,@extra_field_list
,@sortBy
,@sortOrder
,@pageSize
,@pageNumber
END
-- 쿠폰 구매시 바로 적용
IF @flag = 'RewardCoupon'
BEGIN
IF EXISTS (SELECT 'X' FROM CouponSetup CS
WHERE rowId = @schemeId AND endDate >= GETDATE() AND isActive = 'Y')
BEGIN
SELECT @customerId = customerId FROM customerMaster WHERE email = @email
-- 만료기간은 처음 쿠폰 셋업에 셋팅한 날짜 기준으로한다.
SELECT @endDate = endDate FROM CouponSetup WHERE rowId = @schemeId
UPDATE ProductOrder
SET orderType = '1', -- 1:주문, 9:취소
orderStatus = '3',
recvBy = @user,
recvDate = GETDATE()
WHERE orderId = @orderId
INSERT INTO CouponIssue (customerId,couponId,startDate,endDate,createdDate,createdBy,isActive,usedCount)
VALUES (@customerId,@schemeId,GETDATE(),@endDate,GETDATE(),'SYSTEM','Y',0)
EXEC proc_errorHandler 0, 'The Order is Success.', @@IDENTITY
RETURN
END
EXEC proc_errorHandler 1, 'CouponSetUp Error.', NULL
END