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.
 
 
 

402 lines
14 KiB

CREATE OR ALTER PROC proc_TransactionModification
@flag VARCHAR(50) = NULL
,@controlNo VARCHAR(20) = NULL
,@rowId INT = NULL
,@newValue VARCHAR(500) = NULL
,@oldValue VARCHAR(500) = NULL
,@changeType VARCHAR(200) = NULL
,@user VARCHAR(100) = NULL
,@ScChargeMod MONEY = NULL
,@createdBy VARCHAR(100) = NULL
,@fieldValue VARCHAR(MAX) = NULL
,@fieldName VARCHAR(MAX) = NULL
,@pageNumber INT = NULL
,@branchId INT = NULL
,@tranId BIGINT = NULL
,@apiSuccess CHAR(1) = NULL
AS
SET NOCOUNT ON;
BEGIN TRY
DECLARE @message VARCHAR(100)
,@encryptedControlNo VARCHAR(100)
,@pCountry VARCHAR(100)
,@MAXID INT
,@MINID INT
,@modifyId INT
,@payoutPartner VARCHAR(20)
/* For Modification */
DECLARE @FirstName VARCHAR(100)
,@MiddleName VARCHAR(100)
,@LastName VARCHAR(100)
,@lastName1 VARCHAR(100)
,@LastName2 VARCHAR(100)
,@xml XML
,@receiverName VARCHAR(200)
,@senderName VARCHAR(200)
,@isPatner CHAR(1)
,@Paystatus VARCHAR(20)
,@tranStatus VARCHAR(20)
/*
393228 CONTACT Settling Agent
393863 DUTCH-BANGLA BANK LTD.
415208 Xpress Money Settling Agent
*/
IF @controlNo IS NOT NULL
SELECT @encryptedControlNo = dbo.FNAEncryptString(@controlNo)
SELECT TOP 1 @tranId = id,@Paystatus = payStatus, @isPatner = CASE WHEN pAgent IN(393228,393864,415208,585120) THEN 'Y' ELSE 'N' END
,@payoutPartner = CASE WHEN pAgent ='393228' THEN 'CONTACT'
WHEN pAgent ='393864' THEN 'DBBL'
WHEN pAgent ='415208' THEN 'XPRESS'
WHEN pAgent ='585120' THEN 'KORONAPAY'
END
,@tranStatus=tranStatus
FROM dbo.remitTran (NOLOCK)
WHERE controlNo = @encryptedControlNo
IF @flag = 'i' -->> TXN modification Rquest part
BEGIN
IF (@fieldName ='accountNo' AND LEN(@newValue) < 5)
BEGIN
EXEC proc_errorHandler 0,'Account number field is out of range. Min Size 5 characters.',NULL
RETURN
END
IF (@fieldName ='senderName' AND LEN(@newValue) > 100)
BEGIN
EXEC proc_errorHandler 0,'Sender name field is out of range. Max Size 100 characters.',NULL
RETURN
END
IF (@fieldName ='receiverName' AND LEN(@newValue) > 100)
BEGIN
EXEC proc_errorHandler 0,'Receiver name field is out of range. Max Size 100 characters.',NULL
RETURN
END
IF (@fieldName ='rAddress' AND LEN(@newValue) > 150)
BEGIN
EXEC proc_errorHandler 0,'Receiver address field is out of range. Max Size 100 characters.',NULL
RETURN
END
IF (@fieldName ='rContactNo' AND LEN(@newValue) > 20)
BEGIN
EXEC proc_errorHandler 0,'Receiver contact field is out of range. Max Size 20 characters.',NULL
RETURN
END
IF (@fieldName ='rIdNo' AND LEN(@newValue) > 50)
BEGIN
EXEC proc_errorHandler 0,'Receiver id number field is out of range. Max Size 50 characters.',NULL
RETURN
END
IF EXISTS(
SELECT 'X' FROM tranModifyLog
WHERE fieldName = @fieldName
AND [status] = 'Request'
AND controlNo = @encryptedControlNo
)
BEGIN
EXEC proc_errorHandler 0,'Transaction already requested for modification',NULL
RETURN
END
IF EXISTS(SELECT 'A' FROM remitTran(nolock) where controlNo = @encryptedControlNo)
BEGIN
SELECT @tranId = rt.id, @oldValue = CASE
WHEN @fieldName ='rIdType' THEN ISNULL(c.idType, c.idType2)
WHEN @fieldName ='rAddress' THEN c.address
WHEN @fieldName ='rContactNo' THEN c.mobile
WHEN @fieldName ='rIdNo' THEN c.idNumber
WHEN @fieldName ='accountNo' THEN rt.accountNo
WHEN @fieldName ='senderName' THEN b.firstName + ISNULL(' '+b.middleName,'') + ISNULL(' '+b.lastName1,'') + ISNULL(' '+b.lastName2,'')
WHEN @fieldName ='receiverName' THEN c.firstName + ISNULL(' '+c.middleName,'') + ISNULL(' '+c.lastName1,'') + ISNULL(' '+c.lastName2,'')
END
FROM remitTran rt WITH(NOLOCK)
INNER JOIN tranSenders b WITH(NOLOCK) ON rt.id=b.tranId
INNER JOIN tranReceivers c WITH(NOLOCK) ON rt.id=c.tranId
WHERE rt.controlNo = @encryptedControlNo
-->> ## INSERTING REQUESTED LIST
INSERT INTO tranModifyLog(tranId,controlNo, MESSAGE, createdBy, createdDate,status ,fieldName , fieldValue,msgType,oldValue)
SELECT @tranId,@encryptedControlNo,ISNULL(@changeType,'NULL')+' [<b>'+isnull(@oldValue,'')+'</b>] has been requested to change by [<b>' + ISNULL(@newValue, 'NULL')+'</b>]', @user, GETDATE(),'Request',@fieldName,@fieldValue,'MODIFY',@oldValue
-->> ## SELECTING REQUESTED LIST
SELECT [message],ScChargeMod,rowId FROM tranModifyLog(NOLOCK)
WHERE [status] = 'Request' AND controlNo = @encryptedControlNo
END
END
ELSE IF @flag = 'update'
BEGIN
IF NOT EXISTS(SELECT 'X' FROM tranModifyLog(NOLOCK) WHERE [status] = 'Request' AND controlNo = @encryptedControlNo AND createdBy = @user)
BEGIN
EXEC proc_errorHandler 1,'Please add the modification detail!',@controlNo
RETURN;
END
IF @isPatner = 'Y'
BEGIN
IF OBJECT_ID('tempdb..#TEMPTABLE') IS NOT NULL
DROP TABLE #TEMPTABLE
CREATE TABLE #TEMPTABLE
(
tranId INT NULL,
modifyId INT NULL,
fieldName VARCHAR(100) NULL,
fieldValue VARCHAR(MAX) NULL,
oldValue VARCHAR(500) NULL,
MSG VARCHAR(MAX) NULL
)
INSERT INTO #TEMPTABLE(tranId,modifyId,fieldName,fieldValue,oldValue,MSG)
SELECT @tranId,rowId,fieldName,fieldValue,oldValue,message
FROM tranModifyLog(NOLOCK)
WHERE tranId = @tranId AND STATUS = 'Request'
AND createdBy = @user
ALTER TABLE #TEMPTABLE ADD rowId INT IDENTITY(1,1)
SELECT @MAXID = MAX(rowId) FROM #TEMPTABLE
SET @MINID = 1
WHILE @MAXID >= @MINID
BEGIN
SELECT @modifyId = modifyId,
@fieldName = fieldName,
@fieldValue = fieldValue,
@oldValue = oldValue
FROM #TEMPTABLE WITH(NOLOCK)
WHERE rowId = @MINID
IF @fieldName = 'senderName'
BEGIN
SET @xml = @fieldValue
SELECT
@firstName = p.value('@firstName','VARCHAR(50)')
,@middleName = p.value('@middleName','VARCHAR(50)')
,@lastName1 = p.value('@firstLastName','VARCHAR(50)')
,@lastName2 = p.value('@secondLastName','VARCHAR(50)')
FROM @xml.nodes('/root/row') AS tmp(p)
SELECT @firstName = UPPER(@firstName), @middleName = UPPER(@middleName), @lastName1 = UPPER(@lastName1), @lastName2 = UPPER(@lastName2)
SET @senderName = @firstName + ISNULL(' '+@middleName,'') + ISNULL(' '+@lastName1,'') + ISNULL(' '+@lastName2,'')
UPDATE tranSenders SET
firstName = ISNULL(@firstName,'')
,middleName = ISNULL(@middleName,'')
,lastName1 = ISNULL(@lastName1,'')
,lastName2 = ISNULL(@lastName2,'')
,fullName = @senderName
WHERE tranId = @tranId
UPDATE remitTran SET
senderName = @senderName
WHERE id = @tranId
SET @message = 'Sender Name [<b>'+@oldValue+'</b>] has been replaced to [<b>' + ISNULL(@firstName, '') + ISNULL(' ' + @middleName, '') + ISNULL(' ' + @lastName1, '') + ISNULL(' ' +@lastName2, '')+'</b>]'
END
ELSE IF @fieldName = 'receiverName'
BEGIN
SET @xml = @fieldValue
SELECT
@firstName = p.value('@firstName','VARCHAR(50)')
,@middleName = p.value('@middleName','VARCHAR(50)')
,@lastName1 = p.value('@firstLastName','VARCHAR(50)')
,@lastName2 = p.value ('@secondLastName','VARCHAR(50)')
FROM @xml.nodes('/root/row') AS tmp(p)
SELECT @firstName = UPPER(@firstName), @middleName = UPPER(@middleName), @lastName1 = UPPER(@lastName1), @lastName2 = UPPER(@lastName2)
SET @receiverName = @firstName + ISNULL(' ' + @middleName, '') + ISNULL(' ' + @lastName1, '') + ISNULL(' ' + @lastName2, '')
UPDATE tranReceivers SET
firstName = ISNULL(@firstName,'')
,middleName = ISNULL(@middleName,'')
,lastName1 = ISNULL(@lastName1,'')
,lastName2 = ISNULL(@lastName2,'')
,fullName = @receiverName
WHERE tranId = @tranId
UPDATE remitTran SET
receiverName = @receiverName
WHERE id = @tranId
SET @message = 'Receiver Name [<b>'+@oldValue+'</b>] has been replaced to [<b>' + ISNULL(@firstName, '') + ISNULL(' ' + @middleName, '') + ISNULL(' ' + @lastName1, '') + ISNULL(' ' + @lastName2, '')+'</b>]'
END
ELSE IF @fieldName = 'rIdType'
BEGIN
UPDATE tranReceivers SET idType = @fieldValue WHERE tranId = @tranId
SET @message = 'Receiver Id Type [<b>'+ISNULL(@oldValue, '') +'</b>] has been replaced to [<b>'+isnull(@fieldValue,'')+'</b>]'
END
ELSE IF @fieldName = 'rAddress'
BEGIN
UPDATE tranReceivers SET address = @fieldValue WHERE tranId = @tranId
SET @message = 'Receiver Address [<b>'+ISNULL(@oldValue, '')+'</b>] has been replaced to [<b>'+isnull(@fieldValue,'')+'</b>]'
END
ELSE IF @fieldName = 'rContactNo'
BEGIN
UPDATE tranReceivers SET mobile = @fieldValue WHERE tranId = @tranId
SET @message = 'Receiver Contact No [<b>'+ISNULL(@oldValue, '')+'</b>] has been replaced to [<b>'+isnull(@fieldValue,'')+'</b>]'
END
ELSE IF @fieldName = 'rIdNo'
BEGIN
UPDATE tranReceivers SET idNumber = @fieldValue WHERE tranId = @tranId
SET @message = 'Receiver ID No [<b>'+ISNULL(@oldValue, '')+'</b>] has been replaced to [<b>'+isnull(@fieldValue,'')+'</b>]'
END
ELSE IF @fieldName = 'accountNo'
BEGIN
UPDATE remitTran SET accountNo = @fieldValue WHERE id = @tranId
SET @message = 'Receiver Bank Ac No [<b>'+ISNULL(@oldValue, '')+'</b>] has been replaced to [<b>'+isnull(@fieldValue,'')+'</b>]'
END
UPDATE tranModifyLog SET
MESSAGE = @message
,MsgType = 'MODIFY'
,status = CASE WHEN @Paystatus = 'Unpaid' AND @tranStatus = 'Payment' THEN 'ModificationRequest'
WHEN @Paystatus = 'Post' AND @tranStatus = 'Payment' THEN 'ModificationRequest'
END
,resolvedBy = CASE WHEN @Paystatus = 'Unpaid' AND @tranStatus = 'Payment' THEN @user ELSE RESOLVEDBY END
,resolvedDate = CASE WHEN @Paystatus = 'Unpaid' AND @tranStatus = 'Payment' THEN GETDATE() ELSE resolvedDate END
WHERE rowId = @modifyId AND status = 'Request'
SET @MINID = @MINID + 1
END
UPDATE remitTran
SET tranStatus = CASE WHEN @Paystatus = 'Unpaid' AND tranStatus = 'Payment' THEN tranStatus
WHEN @Paystatus = 'Post' AND tranStatus = 'Payment' THEN 'ModificationRequest'
ELSE tranStatus
END
WHERE controlNo = @encryptedControlNo
AND tranStatus = 'Payment' AND payStatus IN('UNPAID','POST')
SELECT '0' errorCode,'The modification request has been completed.' Msg,@controlNo id, @isPatner Extra
RETURN
END
ELSE
BEGIN
-->> UPDATE LOCAL DB STATUS AS ModificationRequest
UPDATE remitTran
SET tranStatus = 'ModificationRequest'
WHERE controlNo = @encryptedControlNo
AND tranStatus = 'Payment' AND payStatus IN('UNPAID','POST')
SELECT '0' errorCode,'The modification request has been processed.GME Remit Help Desk will get back to you shortly' Msg,@controlNo id, @isPatner Extra
RETURN
END
END
ELSE IF @flag = 'details'
BEGIN
IF EXISTS(SELECT 'A' FROM remitTran(nolock) where controlNo = @encryptedControlNo AND tranStatus = 'ModificationRequest' )
BEGIN
IF @payoutPartner = 'KORONAPAY'
BEGIN
SELECT TOP 1
firstName = tr.firstName
,middleName = ISNULL(tr.middleName,'')
,lastName = ISNULL(tr.lastName1,'') + ISNULL(' ' +tr.lastName2,'')
,phone = ISNULL(tr.mobile,'')
,GmeControlNo = ISNULL(rt.ContNo,'')--- unique id send from api response
,RefrenceNo = ISNULL(rt.ContNo,'')--- unique id send from api response
,rt.payStatus
,providerName = 'KORONAPAY'
FROM remitTran rt WITH(NOLOCK)
INNER JOIN tranReceivers tr WITH(NOLOCK) ON rt.id = tr.tranId
WHERE rt.controlNo = @encryptedControlNo
AND tranStatus = 'ModificationRequest'
RETURN
END
ELSE IF @payoutPartner = 'CONTACT'
BEGIN
EXEC PROC_SCHEDULER_PUSH_TXN_CONTACT @flag='modification-request',@ControlNo = @controlNo
RETURN
END
ELSE IF @payoutPartner = 'XPRESS'
BEGIN
EXEC PROC_SCHEDULAR_UPDATE_TXN_XPRESS @flag='modification-request',@ControlNo = @controlNo
RETURN
END
ELSE IF @payoutPartner = 'DBBL'
BEGIN
EXEC PROC_SCHEDULAR_PUSH_TXN_DBBL @flag='modification-request',@ControlNo = @controlNo
RETURN
END
ELSE IF @payoutPartner = 'MONEYGRAM'
BEGIN
SELECT
'601410' AS PartnerId
,dbo.FNADecryptString(controlNo) AS ControlNo
,id AS TranId
,'http://localhost:59420/MoneyGram' AS [url]
, '62412ABE-2CBB-4EB6-8584-45F5FFFD2FE3' AS [authorization]
FROM dbo.remitTran(NOLOCK)
WHERE ControlNo = dbo.FNAEncryptString(@controlNo)
RETURN
END
END
END
ELSE IF @flag='statusUpdate'
BEGIN
IF @apiSuccess = 'Y'
BEGIN
UPDATE remitTran
SET tranStatus = 'Payment'
WHERE controlNo = @encryptedControlNo AND tranStatus = 'ModificationRequest'
-->> ## INSERTING REQUESTED LIST
INSERT INTO tranModifyLog(tranId,controlNo, MESSAGE, createdBy, createdDate,status ,msgType,resolvedBy,resolvedDate)
SELECT @tranId,@encryptedControlNo,'Thirdparty API Modification request success', @user, GETDATE(),'Approved','MODIFY',@user,GETDATE()
EXEC proc_errorHandler 0,'Modification request success',@controlNo
RETURN;
END
ELSE
BEGIN
-->> ## INSERTING REQUESTED LIST
INSERT INTO tranModifyLog(tranId,controlNo, MESSAGE, createdBy, createdDate,status ,msgType)
SELECT @tranId,@encryptedControlNo,'Thirdparty API Modification request failed', 'system', GETDATE(),'Not Resolved','MODIFY'
EXEC proc_errorHandler 1,'Modification request failed from partner',@controlNo
RETURN;
END
END
ELSE IF @flag='showModifiedLog'
BEGIN
SELECT
ROW_NUMBER() OVER(ORDER BY ROWID) [SN],
message [Message]
FROM tranModifyLog WITH(NOLOCK)
WHERE controlNo = @encryptedControlNo AND status = 'ModificationRequest'
UPDATE tranModifyLog SET
resolvedDate = GETDATE()
,resolvedBy = @user
,status = 'Approved'
WHERE controlNo = @encryptedControlNo AND status ='ModificationRequest'
RETURN
END
END TRY
BEGIN CATCH
IF @@TRANCOUNT > 0
ROLLBACK TRANSACTION
DECLARE @errorMessage VARCHAR(MAX)
SET @errorMessage = ERROR_MESSAGE()
EXEC proc_errorHandler 1, @errorMessage, @rowId
END CATCH