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.
 
 
 

194 lines
4.9 KiB

SET QUOTED_IDENTIFIER ON
SET ANSI_NULLS ON
GO
CREATE PROC [dbo].[ws_proc_AccountDepositMarkPaid] (
@ACCESSCODE VARCHAR(50),
@USERNAME VARCHAR(50),
@PASSWORD VARCHAR(50),
@AGENT_SESSION_ID VARCHAR(50),
@xml XML
)
AS
/*
SELECT payStatus, tranStatus, pagent, * from remitTran (NOLOCK) where controlNo = dbo.encryptdb('20160070325780018')
EXEC ws_proc_AccountDepositMarkPaid @ACCESSCODE = 'IMENPADB001', @USERNAME = 'adbapiuser', @PASSWORD = 'adb@API#user!', @AGENT_SESSION_ID = 'y5i0mhyntloih15',
@xml = '<root><row>20160070325780018</row></root>'
DECLARE @xml XML = '<root><row>20160070325780018</row></root>'
SELECT ICN= dbo.encryptdb(p.value('(text())[01]', 'VARCHAR(100)')) FROM @xml.nodes('/root/row') n1(p)
*/
SET NOCOUNT ON;
SET XACT_ABORT ON;
BEGIN TRY
DECLARE @errCode INT
DECLARE @count INT
--EXEC ws_proc_checkAuthntication @USERNAME, @PASSWORD, @ACCESSCODE, @errCode OUT
DECLARE @autMsg VARCHAR(500)
EXEC ws_proc_checkAuthntication @USERNAME,@PASSWORD,@ACCESSCODE,@errCode OUT, @autMsg OUT
DECLARE @errorTable TABLE(
AGENT_SESSION_ID VARCHAR(150)
,REFNO VARCHAR(50)
,SENDER_NAME VARCHAR(100)
,RECEIVER_NAME VARCHAR(100)
,PAYOUTAMT MONEY
,PAYOUTCURRENCY VARCHAR(3)
,STATUS VARCHAR(30)
,STATUS_DATE VARCHAR(20)
,PAY_TOKEN_ID INT
)
INSERT INTO @errorTable(AGENT_SESSION_ID)
SELECT @AGENT_SESSION_ID
IF(@errCode = '1')
BEGIN
SELECT '1002' CODE, ISNULL(@autMsg,'Authentication Fail') MESSAGE, * FROM @errorTable
RETURN
END
IF EXISTS(SELECT 'A' FROM applicationUsers WITH (NOLOCK) WHERE
userName = @USERNAME AND forceChangePwd = 'Y')
BEGIN
SELECT '1002' CODE
,'You logged on first time,must first change your password and try again' MESSAGE
,@AGENT_SESSION_ID AGENT_SESSION_ID
RETURN
END
------------------VALIDATION-------------------------------
IF @AGENT_SESSION_ID IS NULL
BEGIN
SELECT
'1001' CODE
,'AGENT SESSION ID Field is Required' MESSAGE
,@AGENT_SESSION_ID AGENT_SESSION_ID
RETURN;
END
IF @xml IS NULL
BEGIN
SELECT
'1001' CODE
,'CONTROL NO LIST Field is Required' MESSAGE
,@AGENT_SESSION_ID AGENT_SESSION_ID
RETURN;
END
DECLARE
@pAgent INT
,@tranId INT
,@tranStatus VARCHAR(50)
,@pAgentName varchar(200)
,@pAgentCountry varchar(200)
-- PICK AGENTID ,COUNTRY FROM USER
SELECT
@pAgent = agentId
FROM applicationUsers WITH(NOLOCK)
WHERE userName = @USERNAME AND ISNULL(isDeleted, 'N') = 'N' AND isActive = 'Y'
SELECT @pAgentName = agentName,@pAgentCountry=agentCountry FROM agentMaster WITH(NOLOCK)
WHERE agentId = @pAgent AND isActive = 'Y' AND ISNULL(isDeleted, 'N') = 'N'
DECLARE @controlNoTable TABLE(controlNo VARCHAR(50),tranId BIGINT)
INSERT INTO @controlNoTable(controlNo)
SELECT ICN= dbo.FNAEncryptString(p.value('(text())[01]', 'VARCHAR(100)'))
FROM @xml.nodes('/root/row') n1(p)
SELECT controlNo,id INTO #TEMP FROM REMITTRAN(NOLOCK)
WHERE pAgent = @pAgent
AND payStatus = 'Post' AND tranStatus = 'Payment'
AND pCountry = @pAgentCountry AND postedBy = @USERNAME
IF NOT EXISTS(SELECT 'X' FROM @controlNoTable )
BEGIN
SELECT
'1004' CODE
,'Record not found.' MESSAGE
,@AGENT_SESSION_ID AGENT_SESSION_ID
RETURN
END
IF NOT EXISTS(SELECT 'X' FROM #TEMP )
BEGIN
SELECT
'1004' CODE
,'Record not found.' MESSAGE
,@AGENT_SESSION_ID AGENT_SESSION_ID
RETURN
END
IF EXISTS(
SELECT 'X' FROM @controlNoTable icn
LEFT JOIN #TEMP rt (NOLOCK) ON icn.controlNo = rt.controlNo
WHERE rt.controlNo IS NULL
)
BEGIN
SELECT
'1004' CODE
,'Invalid pin no provided in list.' MESSAGE
,@AGENT_SESSION_ID AGENT_SESSION_ID
RETURN
END
DELETE icn FROM @controlNoTable icn
LEFT JOIN #TEMP rt ON icn.controlNo = rt.controlNo
WHERE rt.controlNo IS NULL
IF NOT EXISTS(SELECT 'X' FROM @controlNoTable)
BEGIN
SELECT
'1004' CODE
,'There are no Transaction(s) with the given Token ID to be marked as paid' MESSAGE
,@AGENT_SESSION_ID AGENT_SESSION_ID
RETURN
END
UPDATE remitTran SET
tranStatus = 'Paid'
,payStatus = 'Paid'
,paidBy = @USERNAME
,paidDate = GETDATE()
,paidDateLocal = GETDATE()
,lockStatus = 'unlocked'
FROM remitTran rt with(nolock)
INNER JOIN @controlNoTable td on rt.controlNo = td.controlNo
WHERE RT.pAgent = @pAgent
AND payStatus = 'Post' AND tranStatus = 'Payment'
AND pCountry = @pAgentCountry AND postedBy = @USERNAME
SET @count = @@ROWCOUNT
SELECT
0 CODE
,@AGENT_SESSION_ID AGENT_SESSION_ID
,CAST(@count AS VARCHAR(10)) + ' transaction(s) paid' MESSAGE
END TRY
BEGIN CATCH
SELECT '9001' CODE, 'Technical Error : ' + ERROR_MESSAGE() MESSAGE
INSERT INTO Logs (errorPage, errorMsg, errorDetails, createdBy, createdDate)
SELECT 'API SP Error','Technical Error : ' + ERROR_MESSAGE() MESSAGE,'ws_proc_AccountDepositMarkPaid',@USERNAME, GETDATE()
END CATCH
/*
EXEC ws_proc_AccountDepositMarkeDownloaded
@ACCESSCODE='',
@USERNAME ='',
@PASSWORD='',
@AGENT_SESSION_ID='',
@DOWNLOAD_TOKENID=''
*/
GO