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.
 
 
 

418 lines
15 KiB

SET QUOTED_IDENTIFIER ON
SET ANSI_NULLS ON
GO
/*
mobile_proc_txnDetail @flag='detail'
*/
ALTER PROC mobile_proc_txnDetail(
@flag VARCHAR(100)=NULL
,@User VARCHAR(100)=NULL
,@SenderId VARCHAR(100)=NULL
,@ReceiverId VARCHAR(100)=NULL
,@DeliveryMethodId VARCHAR(100)=NULL
,@PBranch VARCHAR(100)=NULL
,@PAgent VARCHAR(100)=NULL
,@PCurr VARCHAR(100)=NULL
,@CollCurr VARCHAR(100)=NULL
,@CollAmt VARCHAR(100)=NULL
,@PayoutAmt VARCHAR(100)=NULL
,@TransferAmt VARCHAR(100)=NULL
,@ServiceCharge VARCHAR(100)=NULL
,@Discount VARCHAR(100)=NULL
,@ExRate VARCHAR(100)=NULL
,@CalBy VARCHAR(100)=NULL
,@IpAddress VARCHAR(100)=NULL
,@TpExRate VARCHAR(100)=NULL
,@TpPCurr VARCHAR(100)=NULL
,@PayOutPartner VARCHAR(100)=NULL
,@FOREX_SESSION_ID VARCHAR(100)=NULL
,@KftcLogId VARCHAR(100)=NULL
,@PaymentType VARCHAR(100)=NULL
,@IsAgreed VARCHAR(100)=NULL
,@TxnPassword VARCHAR(100)=NULL
,@ProcessId VARCHAR(100)=NULL
,@ReceiverAccountNo VARCHAR(100)=NULL
,@controlNo VARCHAR(30) =NULL
,@tranId BIGINT =NULL
,@Message VARCHAR(200)=NULL
,@Xml XML =NULL
)AS
SET NOCOUNT ON;
SET XACT_ABORT ON;
BEGIN
IF @flag='detail'
BEGIN
DECLARE @ErrorCode VARCHAR(10)='0',@Msg VARCHAR(100)='Success'
IF ISNULL(@IsAgreed,'False') = 'False'
BEGIN
EXEC proc_errorHandler '1','Please agree term and condition.' ,null
RETURN
END
IF @PaymentType NOT IN ('WALLET','AUTODEBIT')
BEGIN
EXEC proc_errorHandler '1','Oops something went wrong,Please relogin and try again.' ,null
RETURN
END
--IF @PaymentType = 'AUTODEBIT'
--BEGIN
-- IF NOT EXISTS(SELECT 'A' FROM KFTC_CUSTOMER_SUB(NOLOCK) WHERE RowId = @KftcLogId)
-- BEGIN
-- EXEC proc_errorHandler '1','Invalid auto debit transaction requested.' ,null
-- RETURN
-- END
--END
IF OBJECT_ID('tempdb..#sender') IS NOT NULL
DROP TABLE #sender
IF OBJECT_ID('tempdb..#receiver') IS NOT NULL
DROP TABLE #receiver
IF EXISTS(SELECT 'A' FROM dbo.customerMaster(NOLOCK) WHERE customerId = @SenderId AND sourceOfFund IS NULL)
UPDATE dbo.customerMaster SET sourceOfFund = 'Family maintenance' WHERE customerId = @SenderId
IF EXISTS(SELECT 'A' FROM dbo.receiverInformation(NOLOCK) WHERE receiverId = @ReceiverId AND purposeOfRemit IS NULL)
UPDATE dbo.receiverInformation SET purposeOfRemit = 'Family maintenance' WHERE receiverId = @ReceiverId
SELECT TOP 1
(SELECT firstName FROM dbo.FNASplitName(CM.firstName)) as SenderFirstName
,(SELECT middleName FROM dbo.FNASplitName(CM.firstName)) as SenderMiddleName
,(SELECT lastName1+ ISNULL(' '+lastName2,'') FROM dbo.FNASplitName(CM.firstName)) as SenderLastName1
,'' SenderLastName2
,CASE WHEN idType='8008' THEN '2059-12-12' ELSE CM.idExpiryDate END as SenderIdExpiryDate
,CM.occupation as SenderOccuption
,FORMAT(CM.dob,'yyyy/MM/dd') as SenderBirthDate
,CASE WHEN @PayOutPartner='415207' THEN '' ELSE CM.email END as SenderEmail
,CM.city as SenderCity
,CM.postalCode as SenderPostalCode
,CM.nativeCountry as SenderNativeCountry
,(SELECT TOP 1 SDV.detailTitle FROM dbo.staticDataValue (NOLOCK)AS SDV WHERE SDV.valueId=CM.idType) as SenderIdType
,CM.idNumber as SenderIdNo
,CM.mobile as SenderMobile
,ISNULL(CM.address,CM.city+',South Korea') as SenderAddress
,sourceOfFund = ISNULL(CM.sourceOfFund,'Family maintenance')
,'1' AS SS
INTO #sender
FROM dbo.customerMaster(NOLOCK) AS CM
WHERE CM.customerId = @SenderId
IF EXISTS(SELECT 'A' FROM receiverInformation(NOLOCK) WHERE receiverId = @ReceiverId AND customerId = @SenderId AND ISNULL(state,'0') ='0')
UPDATE receiverInformation SET state='Any State',district='Any District' WHERE receiverId = @ReceiverId AND customerId = @SenderId
SELECT TOP 1
ReceiverFullName = RI.firstName + ISNULL(' '+RI.middleName,'')+ ISNULL(' '+RI.lastName1,'')+ ISNULL(' '+RI.lastName2,'')
,RI.firstName AS ReceiverFirstName
,ReceiverMiddleName = CASE WHEN LEN(RI.lastName2)>1 AND RI.country='Uzbekistan' THEN RI.middleName +ISNULL(' '+RI.lastName1,'') ELSE RI.middleName END
,ReceiverLastName = CASE WHEN LEN(RI.lastName2)>1 AND RI.country='Uzbekistan' THEN RI.lastName2 ELSE ISNULL(RI.lastName1,'')+ISNULL(' '+RI.lastName2,'') END
----,ISNULL(RI.lastName1,'')+ISNULL(' '+RI.lastName2,'') as ReceiverLastName
,'' as ReceiverIdType
,'' as ReceiverIdNo
,'' as ReceiverIdValid
,'' as ReceiverDob
,RI.homePhone as ReceiverTel
,RI.mobile as ReceiverMobile
,RI.nativeCountry as ReceiverNativeCountry
,ISNULL(RI.city,RI.address) as ReceiverCity
,RI.address as ReceiverAdd1
,RI.email as ReceiverEmail
,UPPER(@ReceiverAccountNo) AS ReceiverAccountNo
,CM.countryName as ReceiverCountry
,CM.countryId as ReceiverCountryId
,swl.rowId AS RState
,RI.state AS RStateText
,Sl.rowId AS RLocation
,RI.district AS RLocationText
,'1' AS RR
,RI.purposeOfRemit
,RI.relationship
INTO #receiver
FROM dbo.receiverInformation(NOLOCK) AS RI
INNER JOIN dbo.countryMaster(NOLOCK) AS CM ON RI.country=CM.countryName
LEFT JOIN dbo.tblSubLocation (NOLOCK) sl ON sl.subLocation=ri.district
LEFT JOIN dbo.tblServicewiseLocation (NOLOCK) swl ON swl.location=ri.state
WHERE RI.receiverId = @ReceiverId
AND RI.customerId = @SenderId
DECLARE @PBranchName VARCHAR(100),@PAgentName VARCHAR(100)
SELECT @PBranchName = AM.agentName FROM dbo.agentMaster(NOLOCK) AS AM WHERE AM.agentId = @PBranch
SELECT @PAgentName = AM.agentName FROM dbo.agentMaster(NOLOCK) AS AM WHERE AM.agentId = @PAgent
--415207:xpress money, Pakistan bank branch is required (live only)
SET @PBranchName = CASE WHEN @PayOutPartner = '415207' AND @PBranchName IS NULL THEN 'Any Branch' ELSE @PBranchName END
--SELECT * FROM #sender AS S
--SELECT * FROM #receiver AS R
----## USED FOR RIA
DECLARE @partnerCostRate MONEY , @PaymentAmount DECIMAL(8,2)=0.0
SELECT @partnerCostRate = pCurrCostRate FROM dbo.exRateCalcHistory(NOLOCK) WHERE FOREX_SESSION_ID = @FOREX_SESSION_ID
IF @PayOutPartner = 393865
SET @PaymentAmount = ROUND(CONVERT(DECIMAL(8,2),CONVERT(MONEY,@PayoutAmt)/@partnerCostRate),2)
SELECT
@ErrorCode AS ErrorCode
,@Msg AS Msg
,@User as [User]
,@SenderId as SenderId
,S.*
,@ReceiverId as ReceiverId
,R.*
,DeliveryMethod = (select typeTitle from serviceTypeMaster(nolock) where serviceTypeId = @DeliveryMethodId)
,@DeliveryMethodId as DeliveryMethodId
,@PBranch as PBranch
,@PBranchName as PBranchName
,'' as PBranchCity
,@PAgent as PAgent
,@PAgentName as PAgentName
,'M' as PBankType
,@PCurr as PCurr
,@CollCurr as CollCurr
,@CollAmt as CollAmt
,@PayoutAmt as PayoutAmt
,@PaymentAmount as PaymentAmount
,@TransferAmt as TransferAmt
,@ServiceCharge as ServiceCharge
,@Discount as Discount
,@ExRate as ExRate
,@CalBy as CalBy
,PurposeOfRemittance = R.purposeOfRemit
,RelWithSender = R.relationship
,Occupation = S.SenderOccuption
,'' as PayoutMsg
,'2080' as SendingAgent
,'GME Online' as SendingAgentName
,'1008' as SendingSuperAgent
,@IpAddress as IpAddress
,'118' as SCountryId
,'South Korea' as SenderCountry
,'' as AgentRefId
,'2080' as SBranch
,@TpExRate as TpExRate
,@TpPCurr as TpPCurr
,'' as TpRefNo
,'' as TpTranId
,@PayOutPartner as PayOutPartner
,@FOREX_SESSION_ID as FOREX_SESSION_ID
,@KftcLogId as KftcLogId
,@PaymentType as PaymentType
,@ProcessId as ProcessId
,'' as DepositMode
FROM #sender AS S INNER JOIN #receiver AS R ON R.RR=S.SS
END
ELSE IF @flag='track-transaction'
BEGIN
DECLARE @payStatus VARCHAR(100);
IF NOT EXISTS(SELECT 'x' FROM dbo.remitTran(NOLOCK) rt WHERE rt.controlNo=dbo.FNAEncryptString(@controlNo))
BEGIN
SELECT '1' ErrorCode, 'Control No Not Found' Msg, NULL Id
RETURN
END
--@payStatus= CASE WHEN (rt.payStatus='Unpaid' AND rt.transtatus='Payment') THEN 'In Send Queue'
-- WHEN (rt.payStatus = 'Post' AND rt.tranStatus = 'Payment') THEN 'Ready for Payment'
-- WHEN (rt.payStatus='Unpaid' AND rt.transtatus='Hold') THEN 'Waiting for Approval'
-- WHEN (rt.payStatus='Unpaid' AND rt.transtatus='Compliance Hold') THEN 'Waiting for Approval'
-- ELSE rt.payStatus
-- END
SELECT
errorCode='0'
,payStatus=rt.payStatus
,bank=rt.pBankName
,branch=rt.pBankBranchName
,AccountNo=rt.accountNo
,Receiver=rt.receiverName
,SendDate=CONVERT(VARCHAR(10),rt.createdDate,120)
,CollAmt=CAST(rt.cAmt AS DECIMAL)
,PayAmount=rt.pAmt
FROM remittran(NOLOCK) rt
WHERE dbo.FNAEncryptString(@controlNo)=rt.controlNo
END
ELSE IF @flag='amend-transaction'
BEGIN
SET @controlNo = dbo.FNAEncryptString(@controlNo)
select @tranId = id from remittran where holdTranId = @tranId
IF NOT EXISTS(SELECT 'x' FROM dbo.remitTran(NOLOCK) rt WHERE rt.controlNo = @controlNo AND rt.Id = @tranId)
BEGIN
SELECT '1' ErrorCode, 'Wrong Control No/TransactionId.' Msg, NULL Id
--SELECT '1' ErrorCode, 'Hello world.' + dbo.fnadecryptstring(@controlNo) + isnull(cast(@tranId as varchar),'') Msg, NULL Id
RETURN
END
INSERT INTO tranModifyLog(tranId,controlNo,[message],createdBy,createdDate,MsgType,[status] )
SELECT @tranId,@controlNo,'Amend Request: ' + @message,@user,GETDATE(),'MODIFY','REQUEST'
SELECT '0' ErrorCode,'Your request for Amend transaction is successful...' Msg,NULL Id
END
ELSE IF @flag='amend-transaction-v2'
BEGIN
DECLARE @holdTranId BIGINT = NULL, @OldValue VARCHAR(250), @FieldName VARCHAR(100), @FieldValue VARCHAR(250), @TranStatus VARCHAR(50), @PaymentMethod VARCHAR(50)
SELECT IDENTITY(INT, 1, 1) AS RowId
,[ColumnName] = p.value('@CloumnName', 'VARCHAR(100)')
,[ColumnValue] = p.value('@ColumnValue', 'VARCHAR(200)')
INTO #TempAmendTable
FROM @xml.nodes('/root/row') AS tmp ( p );
IF NOT EXISTS (SELECT TOP 1 1 FROM #TempAmendTable)
BEGIN
SELECT '1' ErrorCode, 'No data to amend/update request.' Msg, NULL Id
RETURN
END
SET @controlNo = dbo.FNAEncryptString(@controlNo)
SELECT @holdTranId = holdTranId
, @TranStatus = tranStatus
, @PayStatus = PayStatus
, @PaymentMethod = paymentMethod
FROM remitTran (NOLOCK)
WHERE controlNo = @controlNo
AND createdBy = @User
IF @holdTranId IS NULL
BEGIN
SELECT '2' ErrorCode, 'Invalid transaction.' Msg, NULL Id
RETURN
END
IF @TranStatus IN ('Cancel', 'Paid')
BEGIN
SELECT '3' ErrorCode, 'Transaction can not be requested for amendment/update.' Msg, NULL Id
RETURN
END
IF @PayStatus IN ('Cancel', 'Paid')
BEGIN
SELECT '3' ErrorCode, 'Transaction can not be requested for amendment/update.' Msg, NULL Id
RETURN
END
IF ISNULL(@PaymentMethod, '') <> 'Bank Deposit' AND EXISTS(SELECT * FROM #TempAmendTable WHERE [ColumnName] = 'accountNo')
BEGIN
SELECT '4' ErrorCode, 'Invalid transaction to update account number.' Msg, NULL Id
RETURN
END
IF EXISTS(SELECT 'X'
FROM tranModifyLog TML(NOLOCK)
INNER JOIN #TempAmendTable TMP ON TMP.[ColumnName] = TML.fieldName
WHERE TML.[status] = 'Request'
AND TML.tranId = @holdTranId
)
BEGIN
EXEC proc_errorHandler 5,'Cannot Insert Duplicate Request!',NULL
RETURN
END
ALTER TABLE #TempAmendTable ADD IsUpdated BIT, [NewColumnName] VARCHAR(80)
UPDATE #TempAmendTable SET IsUpdated = 0
UPDATE #TempAmendTable SET [NewColumnName] = [ColumnName]
UPDATE #TempAmendTable SET [NewColumnName] = 'receiverName' WHERE [ColumnName] IN ('firstName', 'LastName', 'MiddleName')
DECLARE @RowId INT, @ReceiverName VARCHAR(250)
WHILE EXISTS(SELECT * FROM #TempAmendTable WHERE IsUpdated = 0)
BEGIN
IF EXISTS(SELECT * FROM #TempAmendTable WHERE IsUpdated = 0 AND [NewColumnName] = 'receiverName')
BEGIN
SELECT @ReceiverName = [ColumnValue]
FROM #TempAmendTable
WHERE IsUpdated = 0
AND [ColumnName] = 'firstName'
SELECT @ReceiverName = ISNULL(@ReceiverName, '')
SELECT @ReceiverName = @ReceiverName + ISNULL(' ' + [ColumnValue], '')
FROM #TempAmendTable
WHERE IsUpdated = 0
AND [ColumnName] = 'MiddleName'
SELECT @ReceiverName = @ReceiverName + ISNULL(' ' + [ColumnValue], '')
FROM #TempAmendTable
WHERE IsUpdated = 0
AND [ColumnName] = 'LastName'
UPDATE #TempAmendTable SET IsUpdated = 1 WHERE IsUpdated = 0 AND [NewColumnName] = 'receiverName'
SELECT @RowId = 0, @fieldName = 'receiverName', @FieldValue = NULL
END
ELSE
BEGIN
SET @ReceiverName = NULL
SELECT @RowId = RowId
, @FieldName = [ColumnName]
, @FieldValue = [ColumnValue]
FROM #TempAmendTable
WHERE IsUpdated = 0
END
--rIdType must be table.column.detailTitle of table.staticDataValue
SELECT @tranId = rt.id
, @OldValue = CASE
WHEN @fieldName = 'rIdType' THEN ISNULL(tr.idType, tr.idType2)
WHEN @fieldName = 'rAddress' THEN tr.address
WHEN @fieldName = 'rContactNo' THEN tr.mobile
WHEN @fieldName = 'rIdNo' THEN tr.idNumber
WHEN @fieldName = 'accountNo' THEN rt.accountNo
WHEN @fieldName = 'receiverName' THEN tr.firstName + ISNULL(' ' + tr.middleName, '') + ISNULL(' ' + tr.lastName1, '') + ISNULL(' ' + tr.lastName2, '')
END
FROM remitTran rt WITH(NOLOCK)
INNER JOIN tranReceivers tr WITH(NOLOCK) ON rt.id = tr.tranId
WHERE rt.holdTranId = @holdTranId
-->> ## INSERTING REQUESTED LIST
INSERT INTO tranModifyLog(tranId,controlNo, MESSAGE, createdBy, createdDate,status ,fieldName , fieldValue,msgType,oldValue)
SELECT @holdTranId,@controlNo,ISNULL(@fieldName, 'NULL')+' [<b>'+isnull(@oldValue,'')+'</b>] has been requested to change by [<b>' + ISNULL(@ReceiverName, @FieldValue)+'</b>]'
, @User, GETDATE(),'REQUEST',@fieldName, ISNULL(@ReceiverName, @FieldValue), 'MODIFY', @oldValue
UPDATE #TempAmendTable SET IsUpdated = 1 WHERE RowId = @RowId
END
UPDATE remitTran
SET tranStatus ='ModificationRequest'
WHERE controlNo=@controlNo
SELECT '0' ErrorCode,'Your request for Amend transaction is successful...' Msg,NULL Id
END
ELSE IF @flag='cancel-transaction'
BEGIN
IF NOT EXISTS(SELECT 'x' FROM dbo.remitTran(NOLOCK) rt WHERE rt.controlNo=dbo.FNAEncryptString(@controlNo) AND (rt.id=@tranId OR rt.holdtranid = @tranId))
BEGIN
SELECT '1' ErrorCode, 'Wrong Control No/TransactionId.' Msg, NULL Id
RETURN
END
IF EXISTS(SELECT 'x' FROM dbo.remitTran(NOLOCK) rt WHERE rt.controlNo=dbo.FNAEncryptString(@controlNo) AND (rt.id=@tranId OR rt.holdtranid = @tranId) AND tranStatus IN ('CancelRequest', 'Cancel') )
BEGIN
SELECT '2' ErrorCode, 'Transaction already cancelled or requested.' Msg, NULL Id
RETURN
END
INSERT INTO tranModifyLog(tranId,controlNo,[message],createdBy,createdDate,MsgType,[status] )
SELECT @tranId,@controlNo,'Cancel Request: ' + @message,@user,GETDATE(),'CANCEL','REQUEST'
INSERT INTO tranCancelrequest(tranId, controlNo, cancelReason, cancelStatus, createdBy, createdDate, tranStatus)
SELECT ID, CONTROLNO, @message, 'CancelRequest', @user, GETDATE(), tranStatus
FROM dbo.remitTran(NOLOCK) rt WHERE rt.controlNo=dbo.FNAEncryptString(@controlNo) AND (rt.id=@tranId OR rt.holdtranid = @tranId)
UPDATE dbo.remitTran SET tranStatus='CancelRequest'
WHERE controlNo=dbo.FNAEncryptString(@controlNo)
AND (id=@tranId OR holdtranid = @tranId)
SELECT '0' ErrorCode,'Your request for Cancel transaction is successful...' Msg,NULL Id
END
END
GO