Skip to content
New issue

Have a question about this project? Sign up for a free GitHub account to open an issue and contact its maintainers and the community.

By clicking “Sign up for GitHub”, you agree to our terms of service and privacy statement. We’ll occasionally send you account related emails.

Already on GitHub? Sign in to your account

Resolved renewal bugs when the product is discontinued and a conversion product is assigned #103

Merged
merged 1 commit into from Nov 10, 2021
Merged
Show file tree
Hide file tree
Changes from all commits
Commits
File filter

Filter by extension

Filter by extension

Conversations
Failed to load comments.
Jump to
Jump to file
Failed to load files.
Diff view
Diff view
215 changes: 130 additions & 85 deletions Empty databases/openIMIS_ONLINE.sql
Expand Up @@ -13307,7 +13307,7 @@ GO

CREATE PROCEDURE [dbo].[uspIsValidRenewal]
(
@FileName NVARCHAR(200),
@FileName NVARCHAR(200) = '',
@XML XML
)
/*
Expand Down Expand Up @@ -13338,12 +13338,8 @@ BEGIN

DECLARE @FromPhoneId INT = 0;
DECLARE @RecordCount INT = 0

--SELECT @FilePath = 'C:/inetpub/wwwroot/IMIS' + FTPPolicyRenewalFolder + '/' + @FileName FROM tblIMISDefaults

--SET @Query = (N'SELECT @XML = (SELECT CAST(X AS XML) FROM OPENROWSET(BULK ''' + @FileName +''',SINGLE_BLOB) AS T(X))')

--EXECUTE sp_executesql @Query,N'@XML XML OUTPUT',@XML OUTPUT
DECLARE @RenewalOrder INT = 0
DECLARE @ResponseStatus INT = 0

SELECT
@RenewalId = T.Policy.query('RenewalId').value('.','INT'),
Expand Down Expand Up @@ -13371,11 +13367,7 @@ BEGIN
AND OfficerCode = @Officer AND CHFID = @CHFID AND PR.RenewalID = @RenewalId


IF @DocStatus ='R'
RETURN -3
ELSE IF @DocStatus ='A'
RETURN -4


--Insert the file details in the tblFromPhone
--Initially we keep to DocStatus REJECTED and once the renewal is accepted we will update the Status
INSERT INTO tblFromPhone(DocType, DocName, DocStatus, OfficerCode, CHFID)
Expand All @@ -13385,38 +13377,71 @@ BEGIN

DECLARE @PreviousPolicyId INT = 0

SELECT @PreviousPolicyId = PolicyId FROM tblPolicyRenewals WHERE ValidityTo IS NULL AND RenewalID = @RenewalId;
SELECT @PreviousPolicyId = PolicyId,@ResponseStatus=ResponseStatus FROM tblPolicyRenewals WHERE ValidityTo IS NULL AND RenewalID = @RenewalId;
IF @ResponseStatus = 1
BEGIN
RETURN - 4
END


DECLARE @Tbl TABLE(Id INT)


;WITH PrevProducts
AS
(
SELECT Prod.ProductCode, Prod.ProdId, OldProd.ProdID PrevProd
FROM tblProduct Prod
LEFT OUTER JOIN tblProduct OldProd ON Prod.ProdId = OldProd.ConversionProdId
WHERE Prod.ValidityTo IS NULL
AND OldProd.ValidityTo IS NULL
AND Prod.ProductCode = @ProductCode
)
INSERT INTO @Tbl(Id)
SELECT TOP 1 I.InsureeID Result
FROM tblInsuree I INNER JOIN tblPolicy PL ON I.FamilyID = PL.FamilyID
INNER JOIN tblProduct PR ON PL.ProdID = PR.ProdID
INNER JOIN PrevProducts PR ON PL.ProdId = PR.ProdId OR PL.ProdId = PR.PrevProd --PL.ProdID = PR.ProdID
WHERE CHFID = @CHFID
AND PR.ProductCode = @ProductCode
AND I.ValidityTo IS NULL
AND PL.ValidityTo IS NULL
UNION ALL
SELECT OfficerID
FROM tblOfficer
WHERE Code =@Officer
AND ValidityTo IS NULL
SELECT OfficerID
FROM tblOfficer
WHERE Code =@Officer
AND ValidityTo IS NULL


DECLARE @FamilyID INT = (SELECT FamilyId from tblInsuree WHERE CHFID = @CHFID AND ValidityTo IS NULL)
DECLARE @ProdId INT
DECLARE @StartDate DATE
DECLARE @ExpiryDate DATE
DECLARE @HasCycle BIT
--PAUL -24/04/2019 INSERTED @@AND tblPolicy.ValidityTo@@ to ensure that query does not include deleted policies
;WITH PrevProducts
AS
(
SELECT Prod.ProductCode, Prod.ProdId, OldProd.ProdID PrevProd
FROM tblProduct Prod
LEFT OUTER JOIN tblProduct OldProd ON Prod.ProdId = OldProd.ConversionProdId
WHERE Prod.ValidityTo IS NULL
AND OldProd.ValidityTo IS NULL
AND Prod.ProductCode = @ProductCode
)
SELECT TOP 1 @ProdId = PR.ProdId, @ExpiryDate = PL.ExpiryDate
FROM tblInsuree I INNER JOIN tblPolicy PL ON I.FamilyID = PL.FamilyID
INNER JOIN PrevProducts PR ON PL.ProdId = PR.ProdId OR PL.ProdId = PR.PrevProd
WHERE CHFID = @CHFID
AND PR.ProductCode = @ProductCode
AND I.ValidityTo IS NULL
AND PL.ValidityTo IS NULL
ORDER BY PL.ExpiryDate DESC;

SELECT TOP 1 @ProdId = tblPolicy.ProdID, @ExpiryDate = tblPolicy.ExpiryDate from tblPolicy INNER JOIN tblProduct ON tblPolicy.ProdID = tblProduct.ProdID WHERE FamilyID = @FamilyID AND tblProduct.ProductCode = @ProductCode AND tblProduct.ValidityTo IS NULL ORDER BY ExpiryDate DESC

IF EXISTS(SELECT 1 FROM tblPremium PR INNER JOIN tblPolicy PL ON PR.PolicyID = PL.PolicyID
WHERE PR.Receipt = @Receipt
AND PL.ProdID = @ProdId
AND PR.ValidityTo IS NULL)
AND PR.ValidityTo IS NULL
AND LEN(PR.Receipt) > 0)

RETURN -1;

Expand All @@ -13427,92 +13452,112 @@ BEGIN
WHERE ValidityTo IS NULL
AND ProdId = @ProdId;

IF @LastRenewalDate < @Date
RETURN -2

SELECT @RecordCount = COUNT(1) FROM @Tbl;
--IF EXISTS(SELECT 1 FROM tblProduct WHERE ProdId = @ProdId AND LEN(StartCycle1) > 0)
-- --CHECK IF IT IS A FREE PRODUCT AND IGNORE GRACE PERIOD RENEWAL, IF IS NOT A FREE PRODUCT RETURN -2
-- IF @LastRenewalDate < @Date
-- BEGIN
-- RETURN -2
-- END
SELECT @RecordCount = COUNT(1) FROM @Tbl;


IF @RecordCount = 2
BEGIN
IF @Discontinue = 'false' OR @Discontinue = N''
BEGIN

--Get policy period
DECLARE @tblPeriod TABLE(StartDate DATE, ExpiryDate DATE, HasCycle BIT)

INSERT INTO @tblPeriod
EXEC uspGetPolicyPeriod @ProdId, @ExpiryDate, @HasCycle OUTPUT;
BEGIN
IF @Discontinue = 'false' OR @Discontinue = N''
BEGIN

DECLARE @tblPeriod TABLE(StartDate DATE, ExpiryDate DATE, HasCycle BIT)
DECLARE @EnrolmentDate DATE =DATEADD(D,1,@ExpiryDate)
INSERT INTO @tblPeriod
EXEC uspGetPolicyPeriod @ProdId, @Date, @HasCycle OUTPUT,'R';

DECLARE @ExpiryDatePreviousPolicy DATE
SELECT @ExpiryDatePreviousPolicy = ExpiryDate FROM tblPolicy WHERE PolicyID=@PreviousPolicyId AND ValidityTo IS NULL
SELECT @StartDate = StartDate, @ExpiryDate = ExpiryDate FROM @tblPeriod;
IF @StartDate < @ExpiryDatePreviousPolicy
UPDATE @tblPeriod SET StartDate=DATEADD(DAY, 1, @ExpiryDatePreviousPolicy)
DECLARE @ExpiryDatePreviousPolicy DATE


IF @HasCycle = 1
SELECT @StartDate = StartDate, @ExpiryDate = ExpiryDate FROM @tblPeriod;
ELSE
SELECT @StartDate = @Date, @ExpiryDate = DATEADD(DAY,-1,DATEADD(MONTH,InsurancePeriod,@Date)) FROM tblProduct WHERE ProdID = @ProdId;
SELECT @ExpiryDatePreviousPolicy = ExpiryDate FROM tblPolicy WHERE PolicyID=@PreviousPolicyId AND ValidityTo IS NULL


IF @HasCycle = 1
BEGIN
SELECT @StartDate = StartDate, @ExpiryDate = ExpiryDate FROM @tblPeriod;
IF @StartDate < @ExpiryDatePreviousPolicy
BEGIN
UPDATE @tblPeriod SET StartDate=DATEADD(DAY, 1, @ExpiryDatePreviousPolicy)
SELECT @StartDate = StartDate, @ExpiryDate = ExpiryDate FROM @tblPeriod;
END
END
ELSE
BEGIN

IF @Date < @ExpiryDate
SELECT @StartDate =DATEADD(D,1,@ExpiryDate), @ExpiryDate = DATEADD(DAY,-1,DATEADD(MONTH,InsurancePeriod,DATEADD(D,1,@ExpiryDate))) FROM tblProduct WHERE ProdID = @ProdId;
ELSE
SELECT @StartDate = @Date, @ExpiryDate = DATEADD(DAY,-1,DATEADD(MONTH,InsurancePeriod,@Date)) FROM tblProduct WHERE ProdID = @ProdId;
END



DECLARE @OfficerID INT = (SELECT OfficerID FROM tblOfficer WHERE Code = @Officer AND ValidityTo IS NULL)
DECLARE @PolicyValue DECIMAL(18,2)
--EXEC @PolicyValue = uspPolicyValue 0, 0,@FamilyID, @ProdId,@Date,
EXEC @PolicyValue = uspPolicyValue
@FamilyId = @FamilyID,
@ProdId = @ProdId,
@EnrollDate = @Date,
@PreviousPolicyId = @PreviousPolicyId,
@PolicyStage = 'R';

DECLARE @PolicyStatus TINYINT = 2
DECLARE @OfficerID INT = (SELECT OfficerID FROM tblOfficer WHERE Code = @Officer AND ValidityTo IS NULL)
DECLARE @PolicyValue DECIMAL(18,2)

SET @EnrolmentDate = @Date
EXEC @PolicyValue = uspPolicyValue
@FamilyId = @FamilyID,
@ProdId = @ProdId,
@EnrollDate = @EnrolmentDate,
@PreviousPolicyId = @PreviousPolicyId,
@PolicyStage = 'R';

IF @Amount < @PolicyValue SET @PolicyStatus = 1
DECLARE @PolicyStatus TINYINT = 2

INSERT INTO tblPolicy(FamilyID, EnrollDate, StartDate, EffectiveDate, ExpiryDate, PolicyStatus, PolicyValue, ProdID, OfficerID, AuditUserID, PolicyStage)
VALUES(@FamilyID, @Date, @StartDate, @StartDate,@ExpiryDate, @PolicyStatus, @PolicyValue, @ProdId, @OfficerID, 0, 'R')
IF @Amount < @PolicyValue SET @PolicyStatus = 1

DECLARE @PolicyID INT = (SELECT SCOPE_IDENTITY())
INSERT INTO tblPolicy(FamilyID, EnrollDate, StartDate, EffectiveDate, ExpiryDate, PolicyStatus, PolicyValue, ProdID, OfficerID, AuditUserID, PolicyStage)
VALUES(@FamilyID, @Date, @StartDate, @StartDate,@ExpiryDate, @PolicyStatus, @PolicyValue, @ProdId, @OfficerID, 0, 'R')

-- No need to create contribution if the payment is not made yet
DECLARE @PolicyID INT = (SELECT SCOPE_IDENTITY())

-- No need to create if the payment is not made yet
IF @Amount > 0
BEGIN
INSERT INTO tblPremium(PolicyID, Amount, Receipt, PayDate, PayType, AuditUserID, PayerID)
Values(@PolicyID, @Amount, @Receipt, @Date, 'C',0, @PayerId)
END



DECLARE @InsureeId INT
DECLARE CurNewPolicy CURSOR FOR SELECT I.InsureeID FROM tblInsuree I
INNER JOIN tblFamilies F ON I.FamilyID = F.FamilyID
INNER JOIN tblPolicy P ON P.FamilyID = F.FamilyID
WHERE P.PolicyId = @PolicyId
AND I.ValidityTo IS NULL
AND F.ValidityTo IS NULL
AND P.ValidityTo IS NULL
OPEN CurNewPolicy;
FETCH NEXT FROM CurNewPolicy INTO @InsureeId;
WHILE @@FETCH_STATUS = 0
BEGIN
EXEC uspAddInsureePolicy @InsureeId;
DECLARE @InsureeId INT
DECLARE CurNewPolicy CURSOR FOR SELECT I.InsureeID FROM tblInsuree I
INNER JOIN tblFamilies F ON I.FamilyID = F.FamilyID
INNER JOIN tblPolicy P ON P.FamilyID = F.FamilyID
WHERE P.PolicyId = @PolicyId
AND I.ValidityTo IS NULL
AND F.ValidityTo IS NULL
AND P.ValidityTo IS NULL
OPEN CurNewPolicy;
FETCH NEXT FROM CurNewPolicy INTO @InsureeId;
END
CLOSE CurNewPolicy;
DEALLOCATE CurNewPolicy;
WHILE @@FETCH_STATUS = 0
BEGIN
EXEC uspAddInsureePolicy @InsureeId;
FETCH NEXT FROM CurNewPolicy INTO @InsureeId;
END
CLOSE CurNewPolicy;
DEALLOCATE CurNewPolicy;

UPDATE tblPolicyRenewals SET ResponseStatus = 1, ResponseDate = GETDATE() WHERE RenewalId = @RenewalId;
END
ELSE
BEGIN
UPDATE tblPolicyRenewals SET ResponseStatus = 2, ResponseDate = GETDATE() WHERE RenewalId = @RenewalId
END
UPDATE tblPolicyRenewals SET ResponseStatus = 1, ResponseDate = GETDATE() WHERE RenewalId = @RenewalId;
END
ELSE
BEGIN
UPDATE tblPolicyRenewals SET ResponseStatus = 2, ResponseDate = GETDATE() WHERE RenewalId = @RenewalId
END

UPDATE tblFromPhone SET DocStatus = N'A' WHERE FromPhoneId = @FromPhoneId;
UPDATE tblFromPhone SET DocStatus = N'A' WHERE FromPhoneId = @FromPhoneId;

SELECT * FROM @Tbl;
END
SELECT * FROM @Tbl;
END
ELSE
BEGIN
RETURN -5
END
END TRY
BEGIN CATCH
SELECT ERROR_MESSAGE()
Expand Down
43 changes: 35 additions & 8 deletions Migration script/openIMIS migration latest.sql
Expand Up @@ -8406,7 +8406,7 @@ GO

CREATE PROCEDURE [dbo].[uspIsValidRenewal]
(
@FileName NVARCHAR(200),
@FileName NVARCHAR(200) = '',
@XML XML
)
/*
Expand Down Expand Up @@ -8485,10 +8485,21 @@ BEGIN

DECLARE @Tbl TABLE(Id INT)


;WITH PrevProducts
AS
(
SELECT Prod.ProductCode, Prod.ProdId, OldProd.ProdID PrevProd
FROM tblProduct Prod
LEFT OUTER JOIN tblProduct OldProd ON Prod.ProdId = OldProd.ConversionProdId
WHERE Prod.ValidityTo IS NULL
AND OldProd.ValidityTo IS NULL
AND Prod.ProductCode = @ProductCode
)
INSERT INTO @Tbl(Id)
SELECT TOP 1 I.InsureeID Result
FROM tblInsuree I INNER JOIN tblPolicy PL ON I.FamilyID = PL.FamilyID
INNER JOIN tblProduct PR ON PL.ProdID = PR.ProdID
INNER JOIN PrevProducts PR ON PL.ProdId = PR.ProdId OR PL.ProdId = PR.PrevProd --PL.ProdID = PR.ProdID
WHERE CHFID = @CHFID
AND PR.ProductCode = @ProductCode
AND I.ValidityTo IS NULL
Expand All @@ -8506,12 +8517,30 @@ BEGIN
DECLARE @ExpiryDate DATE
DECLARE @HasCycle BIT
--PAUL -24/04/2019 INSERTED @@AND tblPolicy.ValidityTo@@ to ensure that query does not include deleted policies
SELECT TOP 1 @ProdId = tblPolicy.ProdID, @ExpiryDate = tblPolicy.ExpiryDate from tblPolicy INNER JOIN tblProduct ON tblPolicy.ProdID = tblProduct.ProdID AND tblPolicy.ValidityTo IS NULL WHERE FamilyID = @FamilyID AND tblProduct.ProductCode = @ProductCode AND tblProduct.ValidityTo IS NULL ORDER BY ExpiryDate DESC

;WITH PrevProducts
AS
(
SELECT Prod.ProductCode, Prod.ProdId, OldProd.ProdID PrevProd
FROM tblProduct Prod
LEFT OUTER JOIN tblProduct OldProd ON Prod.ProdId = OldProd.ConversionProdId
WHERE Prod.ValidityTo IS NULL
AND OldProd.ValidityTo IS NULL
AND Prod.ProductCode = @ProductCode
)
SELECT TOP 1 @ProdId = PR.ProdId, @ExpiryDate = PL.ExpiryDate
FROM tblInsuree I INNER JOIN tblPolicy PL ON I.FamilyID = PL.FamilyID
INNER JOIN PrevProducts PR ON PL.ProdId = PR.ProdId OR PL.ProdId = PR.PrevProd
WHERE CHFID = @CHFID
AND PR.ProductCode = @ProductCode
AND I.ValidityTo IS NULL
AND PL.ValidityTo IS NULL
ORDER BY PL.ExpiryDate DESC;

IF EXISTS(SELECT 1 FROM tblPremium PR INNER JOIN tblPolicy PL ON PR.PolicyID = PL.PolicyID
WHERE PR.Receipt = @Receipt
AND PL.ProdID = @ProdId
AND PR.ValidityTo IS NULL)
AND PR.ValidityTo IS NULL
AND LEN(PR.Receipt) > 0)

RETURN -1;

Expand All @@ -8530,9 +8559,7 @@ BEGIN
-- RETURN -2
-- END
SELECT @RecordCount = COUNT(1) FROM @Tbl;





IF @RecordCount = 2
BEGIN
Expand Down