Browse Source

#24356 job scheduler updated

master
Leeza Baidar 8 months ago
parent
commit
3f7561d8bf
  1. 208
      Deployment/24356-Job_Scheduler/PROC_AUTO_APPROVE_TXN_JOB.sql

208
Deployment/24356-Job_Scheduler/PROC_AUTO_APPROVE_TXN_JOB.sql

@ -1,93 +1,121 @@
ALTER PROCEDURE PROC_AUTO_APPROVE_TXN_JOB
AS
BEGIN
SET NOCOUNT ON;
SET XACT_ABORT ON;
exec PROC_AUTO_APPROVE_TXN_JOB
BEGIN TRY
IF OBJECT_ID('tempdb..#tempTable1') IS NOT NULL
DROP TABLE #tempTable1;
DECLARE @MinAmt MONEY
DECLARE @tranId BIGINT
SELECT @MinAmt = detailDesc
FROM staticDataValue
WHERE typeId = '10200'
CREATE TABLE #tempTable1 (
id BIGINT,
controlNo VARCHAR(100),
amt MONEY
);
INSERT INTO #tempTable1
SELECT id, controlNo, cAmt
FROM remitTranTemp
WHERE tranStatus = 'Hold' AND
payStatus = 'Unpaid' AND
approvedBy IS NULL AND
tranType IN ('M', 'I') AND
verifiedBy IS NOT NULL AND
verifiedDate IS NOT NULL AND
ISNULL(sRouteId,0) in(0,'M') AND
cAmt <= @MinAmt
DECLARE tranCursor CURSOR FOR
SELECT id
FROM #tempTable1
OPEN tranCursor
FETCH NEXT FROM tranCursor INTO @tranId
WHILE @@FETCH_STATUS = 0
BEGIN
BEGIN TRANSACTION
UPDATE remitTranTemp
SET tranStatus =
CASE
WHEN tranStatus IN (
'Hold', 'Compliance Hold', 'OFAC Hold', 'OFAC/Compliance Hold',
'Cash Limit Hold', 'Cash Limit/Compliance Hold',
'Cash Limit/OFAC Hold', 'Cash Limit/OFAC/Compliance Hold'
)
THEN
CASE
WHEN tranStatus = 'Hold' THEN 'Payment'
WHEN tranStatus = 'Compliance Hold' THEN 'Compliance'
WHEN tranStatus = 'OFAC Hold' THEN 'OFAC'
WHEN tranStatus = 'OFAC/Compliance Hold' THEN 'OFAC/Compliance'
WHEN tranStatus = 'Cash Limit Hold' THEN 'Cash Limit'
WHEN tranStatus = 'Cash Limit/Compliance Hold' THEN 'Cash Limit/Compliance'
WHEN tranStatus = 'Cash Limit/OFAC Hold' THEN 'Cash Limit/OFAC'
WHEN tranStatus = 'Cash Limit/OFAC/Compliance Hold' THEN 'Cash Limit/OFAC/Compliance'
ELSE 'Payment'
END
ELSE tranStatus
END,
approvedBy = 'SYSTEM',
approvedDate = GETDATE(),
approvedDateLocal = GETDATE()
WHERE id = @tranId
IF @@ROWCOUNT > 0
COMMIT TRANSACTION
ELSE
ROLLBACK TRANSACTION
FETCH NEXT FROM tranCursor INTO @tranId
END
CLOSE tranCursor
DEALLOCATE tranCursor
RETURN
END TRY
BEGIN CATCH
DECLARE @errorMessage VARCHAR(MAX)
SET @errorMessage = ERROR_MESSAGE()
EXEC proc_errorHandler 1, @errorMessage, NULL
END CATCH
END;
SET NOCOUNT ON;
SET XACT_ABORT ON;
BEGIN TRY
IF OBJECT_ID('tempdb..#tempTable') IS NOT NULL
DROP TABLE #tempTable;
DECLARE @MinAmt MONEY
DECLARE @tranId BIGINT
,@remarks VARCHAR(100)
,@controlNo VARCHAR(200)
SELECT @MinAmt = detailDesc
FROM staticDataValue
WHERE typeId = '10200'
AND valueId = '11486'
CREATE TABLE #tempTable (
id BIGINT
,controlNo VARCHAR(100)
,amt MONEY
,rowId INT
);
INSERT INTO #tempTable
SELECT id
,controlNo
,cAmt
,rowId = 0
FROM remitTranTemp
WHERE tranStatus = 'Hold'
AND payStatus = 'Unpaid'
AND approvedBy IS NULL
AND tranType IN (
'M'
,'I'
)
AND verifiedBy IS NOT NULL
AND verifiedDate IS NOT NULL
AND ISNULL(sRouteId, 0) IN (
0
,'M'
)
AND cAmt <= @MinAmt
WHILE EXISTS (
SELECT TOP 1 1
FROM #tempTable
WHERE rowId = 0
)
BEGIN
SELECT @tranId = id
,@controlNo = controlNo
FROM #tempTable(NOLOCK)
WHERE rowId = 0
CREATE TABLE #tempApprove (
errorCode VARCHAR(10)
,Msg VARCHAR(MAX)
,Id VARCHAR(50)
)
INSERT INTO #tempApprove (
errorCode
,Msg
,Id
)
EXEC proc_ApproveHoldedTXN @flag = 'approve'
,@user = 'SYSTEM'
,@id = @tranId
SET @remarks = 'Auto approved txn by job having less than ' + CONVERT(VARCHAR(50), @MinAmt) + ' GBP'
IF EXISTS (
SELECT *
FROM #tempApprove
WHERE errorCode = 0
)
BEGIN
INSERT INTO tranModifyLog (
tranId
,controlNo
,message
,createdBy
,createdDate
,MsgType
)
SELECT @tranId
,@controlNo
,@remarks
,'SYSTEM'
,GETDATE()
,'Auto Approved Transaction'
EXEC JobHistoryRecord @flag = 'i'
,@job_name = 'PROC_AUTO_APPROVE_TXN_JOB'
,@job_remarks = 'Auto Approved Txn'
,@job_user = 'SYSTEM'
END
DROP TABLE #tempApprove
UPDATE #temptable
SET rowId = 1
WHERE id = @tranId
END
END TRY
BEGIN CATCH
DECLARE @errorMessage VARCHAR(MAX)
SET @errorMessage = ERROR_MESSAGE()
EXEC proc_errorHandler 1
,@errorMessage
,NULL
END CATCH
END;
Loading…
Cancel
Save