Calculate Value Based on Two Date Ranges and Determine Remainder

helpmeplz_

New Member
Joined
Aug 25, 2017
Messages
6
Hi,

Thank you in advance for the help. I have been trying to calculate S8:Y9 for a couple of days now. It's turning into a mess of nested if statements and I'm still having trouble with all dates that I test. Essentially, given an Option of A or B in C8:C9, break out the Accepted Benefit in J8:J9 into the correct fiscal years in S8:Y9 according to the entered Implementation Date and End Date in N8:O9. In R1:Y5, you see the start dates and end dates of the fiscal years according to Option A or B.

My problem is that if I test many different implementation dates, sometimes the formulas break out the FY Benefit into the correct year and sometimes not. I am particularly having an issue with the formulas removing or adding 1 day to a fiscal year than they should, especially if you test implementation dates around the end date of Option A or B, or dates that span many fiscal years.


Please help with S8 to Y9.xlsx
ABCDEFGHIJKLMNOPQRSTUVWXYAE
1Closest Date B:1/31/20211/31/20221/31/20231/31/20241/31/20251/31/20261/31/2027
2Start Date B:2/2/20201/31/20211/30/20221/29/20232/4/20242/2/20252/1/2026
3End Date B:1/30/20211/29/20221/28/20232/3/20242/1/20251/31/20261/30/2027
4Start Date A:9/1/20199/1/20209/1/20219/1/20229/1/20239/1/20249/1/2025
5End Date A:8/31/20208/31/20218/31/20228/31/20238/31/20248/31/20258/31/2026
6Summary$0$0$0$0$0$10,000,000$0$0$9,972,603$27,397$0$0$0$0$0
7Option Accepted Benefit Implementation Date End DateFY20 Benefit (Accepted)FY21 Benefit (Accepted)FY22 Benefit (Accepted)FY23 Benefit (Accepted)FY24 Benefit (Accepted)FY25 Benefit (Accepted)FY26 Benefit (Accepted)FY/CY Check
8A$5,000,0009/1/20198/31/2020$5,000,000$0$0$0$0$0$0 
9B$5,000,0002/2/20202/1/2021$4,972,603$27,397$0$0$0$0$0 
Track
Cell Formulas
RangeFormula
T1:Y1T1=DATE(YEAR(S1)+1,MONTH(S1),DAY(S1))
U2U2=T3+1
S3:Y3S3=IF((TEXT(S1,"ddd")="Sat"),S1+7*(WEEKDAY(S1)>7),IF(ABS((CEILING(S1-1,7))-S1)>ABS((FLOOR(S1-1,7))-S1),FLOOR(S1-1,7),CEILING(S1-1,7)))
M6,E6:K6E6=SUM(E8:E20)
S6:Y6S6=SUM(S8:S21)
S8:S9S8=IF($C8="B",IF(AND($N8<=S$3,OR($N8>=S$2,$O8>=S$2)),IF($N8=S$3,1,S$3-$N8)*($J8/365),0),IF(AND($N8<=S$5,OR($N8>=S$4,$O8>=S$4)),IF($N8=S$3,1,(S$5-$N8))*($J8/365),IF($N8=S$5,1,(S$5+1-$N8))*($J8/365)))
T8:Y8T8=IF($C8="B",IF(IF(AND($N8<=T$3,OR($N8>=T$2,$O8>=T$2)),IF(S$3=$N8,$O8-1-T$2,$O8+1-T$2))>365,IF(AND($N8<=T$3,OR($N8>=T$2,$O8>=T$2)),(IF(T$3=$N8,T$3+1-$N8,T$3-$N8))*($J8/365),0),IF(AND($N8<=T$3,OR($N8>=T$2,$O8>=T$2)),IF(S$3=$N8,$O8-1-T$2,$O8-T$2)*($J8/365),0)),IF(IF(AND($N8<=T$5,OR($N8>=T$4,$O8>=T$4)),IF(S$5=$N8,($O8-1-T$4),$O8+1-T$4))>365,IF(AND($N8<=T$5,OR($N8>=T$4,$O8>=T$4)),IF(T$4=$N8,(T$5-$N8),(T$5+1-$N8))*($J8/365),0),IF(AND($N8<=T$5,OR($N8>=T$4,$O8>=T$4)),IF(S$5=$N8,$O8-T$4,($O8+1-T$4))*($J8/365),0)))
T9:Y9T9=IF($C9="B",IF(IF(AND($N9<=T$3,OR($N9>=T$2,$O9>=T$2)),IF(S$3=$N9,$O9-1-T$2,$O9+1-T$2))>365,IF(AND($N9<=T$3,OR($N9>=T$2,$O9>=T$2)),(IF(T$3=$N9,T$3+1-$N9,T$3-$N9))*($J9/365),0),IF(AND($N9<=T$3,OR($N9>=T$2,$O9>=T$2)),IF(S$3=$N9,$O9-1-T$2,$O9+1-T$2)*($J9/365),0)),IF(IF(AND($N9<=T$5,OR($N9>=T$4,$O9>=T$4)),IF(S$5=$N9,($O9-1-T$4),$O9+1-T$4))>365,IF(AND($N9<=T$5,OR($N9>=T$4,$O9>=T$4)),IF(T$4=$N9,(T$5-$N9),(T$5+1-$N9))*($J9/365),0),IF(AND($N9<=T$5,OR($N9>=T$4,$O9>=T$4)),IF(S$5=$N9,$O9-T$4,($O9+1-T$4))*($J9/365),0)))
O8:O9O8=N8+365
AE8AE8=IF(OR((SUM(S8:Y8)-SUM(Z8:AD8)>0),(SUM(Z8:AD8)-SUM(Z8:AD8)>0)),"Check","")
AE9AE9=IF(OR((SUM(S9:Y9)-SUM(Z9:AD9)>0),(SUM(Z9:AD9)-SUM(S9:Y9)>0)),"Check","")
Cells with Conditional Formatting
CellConditionCell FormatStop If True
AE8:AE9Cell Valuecontains "Check"textNO
Cells with Data Validation
CellAllowCriteria
D8:D9ListCapex,Opex,Both
P8:P9List=#REF!
 

Excel Facts

What do {} around a formula in the formula bar mean?
{Formula} means the formula was entered using Ctrl+Shift+Enter signifying an old-style array formula.
Hi Helpmeplz,

If I've followed you correctly then you can put this formula in S8 then copy across.

Excel Formula:
=CHOOSE(MATCH($C8,{"A","B"},0),($J8/($O8-$N8+1)*(MAX(MIN($O8,S$5)-MAX($N8,S$4)+1,0))),($J8/($O8-$N8+1)*(MAX(MIN($O8,S$3)-MAX($N8,S$2)+1,0))))
 
Upvote 0
Solution

Forum statistics

Threads
1,212,927
Messages
6,110,729
Members
448,294
Latest member
jmjmjmjmjmjm

We've detected that you are using an adblocker.

We have a great community of people providing Excel help here, but the hosting costs are enormous. You can help keep this site running by allowing ads on MrExcel.com.
Allow Ads at MrExcel

Which adblocker are you using?

Disable AdBlock

Follow these easy steps to disable AdBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the icon in the browser’s toolbar.
2)Click on the "Pause on this site" option.
Go back

Disable AdBlock Plus

Follow these easy steps to disable AdBlock Plus

1)Click on the icon in the browser’s toolbar.
2)Click on the toggle to disable it for "mrexcel.com".
Go back

Disable uBlock Origin

Follow these easy steps to disable uBlock Origin

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back

Disable uBlock

Follow these easy steps to disable uBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back
Back
Top