Forum Discussion
Excel formula help
- Jun 15, 2023I'm not sure but I think what the OP is getting at is that the partial payments need to be taken into account such that the 10% is applied to the remaining balance at that time. So if the original loan is 1000 and 10% interest so principle & Interest is 1100 that has to be paid by due date but if only 500 was paid then 600 is outstanding balance and would get 10% penalty so new loan balance would be 660 the month after the due date and if they paid 260 then the next month would have another 10% penalty but only on the remaining 400 so the new balance would be 440.
Maybe Mbarak630 could confirm or correct this
If this is the case I think we could use LAMBDA function with REDUCE to do this
The formular in G5 was pulling payments paid and if the loan is cleared and there be overpayment then the extra amount will be used to pay for the next loan.
Mbarak630 Ok so assuming the prior loan must be paid off before a new loan (no overlapping payments) this should work to calculate the penalties accrued during a loan. Seems overly complicated but couldn't see a more simple way:
=LET(balanceAtDueDate, [@[Principle & Interest]]+SUMIF($C$4:$C4,[@[Customer Name]],$E$4:$E4)+SUMIF($C$4:$C4,[@[Customer Name]],$H$4:$H4)-SUMIFS(Payments[Payment Received Amount (Rs.)],Payments[Customer Name],[@[Customer Name]],Payments[Date],"<="&[@[Due Date]]),
IF((TODAY()>[@[Due Date]])*(balanceAtDueDate>0),
LET(months,DATEDIF([@[Due Date]],TODAY(),"M")+1,
s, SEQUENCE(months),
INDEX(REDUCE(VSTACK(balanceAtDueDate,0),s,LAMBDA(p,q,
LET(penalty, ROUND(INDEX(p,1)*0.1,2),
newbalance, MAX(INDEX(p,1)+penalty-SUMIFS(Payments[Payment Received Amount (Rs.)],Payments[Customer Name],[@[Customer Name]],Payments[Date],">"&EDATE([@[Due Date]],q-1),Payments[Date],"<="&EDATE([@[Due Date]],q)),0),
VSTACK(newbalance,INDEX(p,2)+penalty)
))),
2)),
0))
so in summary line 1 creates and calcs a variable called 'balanceAtDueDate' this is based on all prior loan amounts + prior penalties - all payments to that date (i.e. will incorporate overpayments from prior loans and payments made for this load before due date.
Then (line 2) if we are past that date and the balance is >0 then it will start calculating penalties (else it goes to line 11 and returns 0)
Line 3 sets 'months' to be number of months from due date to today and then Line 4 creates sequence 's' from 1 to that number (1,2,3,... )
Line 5 sets up the recursive call to go month by month (REDUCE) starting with balanceAtDueDate and 0 penalties and looping for each 'months'
So Lines 6-8 get applied for each month after the due date and will:
Line 6 calculate the penalty due to the balance left on the prior month
Line 7 calculates the new balance going into the next month based on prior balance + penalty (line 6) - any payments made this past month
Line 8 just outputs this new balance and updates the total accrued penalty to loop back for the next month
Line 10 is actually part of the INDEX on line 5 which is after that recursive loop is done it just take out the 2nd element, the accumulated penalty
see attached. Once this accumulated penalty is available the other calculations are much easier.
- mtarlerJun 20, 2023Silver Contributor
another update with a cap on the penalties after 3 months
- mtarlerJun 19, 2023Silver Contributor
Mbarak630 OK i re-worked the formula to track the amount paid toward this loan and hence only apply discount on the penalty based on +pays against this loan and cap penalties if pay>base+penalties. Basically this new version should allow for multiple loans 🙂
try it out ...
- Mbarak630Jun 19, 2023Copper Contributor
yes, payments made were and the allocation was given priority to the earlier loans.
I think best is to avoid multiple loans running for one customer, but stick one loan per customer and until it is fully paid inclussive of all penalties and there is no outstanding amount, then a new loan can be
- mtarlerJun 19, 2023Silver ContributorIf I remember correctly the problem is that this formula doesn't track which loan a given payment is being applied to. Technically the 2 loans could overlap as long as the first is paid off before the DUE date of the next. An additional conditional on the penalty accrual function could be added to check if the NET total payment has exceeded all prior loan commitments (i.e. prior loans paid off) and not apply payments until that happens.
- Mbarak630Jun 19, 2023Copper Contributor
You are correct, i was just trying to see if a customer has two loans, what was the effect and i saw the issues arising, and so to avoid it then only one loan for a customer and must be cleared before another is taken.
Also, its better if I use the Loan ID, and the penalties were necessary because if loan wasnt paid by due date, then the penalties apply.
I will replace customer name with Loan ID
- mtarlerJun 19, 2023Silver Contributoryes, as I noted in an earlier message "Please note that I would highly recommend adding the loan reference to the payment sheet (or replace customer name with loan reference). " That said I did try this and it was working but I did make the assumption as you noted that for a given customer "the prior loan must be paid off before a new loan" is issued. If the loans overlap that would cause an issue. IF you change this to be based on a specific loan ID then the formula can be simplified as the whole summation of prior loans and payments and penalties wouldn't be needed.
That all said, you say "I changed the invoice dates for both row 5 and row 6, as 18-feb-23, same customer name, loan amount is same, however cell H6 and I6 have values different to H5 and I5 ." but I don't know what you are saying. Is there something wrong with the calculation? You should expect rows 5 and 6 to be different as they are for 2 different loans and if they are the same customer then I5 better be zero based on the above assumption while I6 will depend on if it paid off yet. Column H is specifically the 'Applied Penalties' accrued for that specific loan (not the total for the customer). - Mbarak630Jun 19, 2023Copper Contributor
I wouldn't say that i fully understood, but after testing the first row 5 and and can say that it was working as i was expecting.
I changed the invoice dates did calculations manualy and saw i was getting same results.
I changed the invoice dates for both row 5 and row 6, as 18-feb-23, same customer name, loan amount is same, however cell H6 and I6 have values different to H5 and I5 .
This got me a little confused
- mtarlerJun 19, 2023Silver ContributorI'm glad it is working as desired and I hope the explanation was help/enough for you to have some understanding of how it is working.