Annual Forecast History

MrDB4Excel

Active Member
Joined
Jan 29, 2004
Messages
348
Office Version
  1. 2013
Platform
  1. Windows
I am having great difficulty with a leap year with respect to the formulas you see in the attached Xl2bb examples.
In the sheet ForecastHistory2023 you will see all the formulas are working correct, but in the sheet ForecastHistory2024 the initial formulas in C5 & C6 and probably consequently throughout the remainder of column “C” where these 2 date formulas exist are not working.
What am I missing?
I have tried several different variations and nothing seems to work.
Any help will be much appreciated.
The first Xl2bb is from sheet ForecastHistory2023
And
The second Xl2bb is from sheet ForecastHistory2024

AnnualForecastHistory.xlsx
ABCDEFGHIJKLM
102023=MAX(DATE(B3,1,1),DATE(B3,1,1)-WEEKDAY(DATE(B3,1,1),2)+(B4)*7+1)
2Week # ð47Monday, November 22, 2021Sunday, November 28, 20211=MIN(DATE(B3+1,1,0),DATE(B3,1,1)-WEEKDAY(DATE(B3,1,1),2)+(B4+1)*7)
3Year2023Mon-02 January 2023Week of January 02toJanuary 081
4Week Number1Week 1 of 2023 January 02 To January 08.png11Week 1 of 2023 January 02 To January 08.pngWeek1of2023January02ToJanuary08
5Start DateJanuary 0212Week 2 of 2023 January 09 To January 15.pngWeek2of2023January09ToJanuary15
6End DateJanuary 08Week 1 of 2023 January 02 To January 08.pngJanuary 02January 0813Week 3 of 2023 January 16 To January 22.pngWeek3of2023January16ToJanuary22
7Year2023Mon-09 January 2023Week of January 09toJanuary 1524Week 4 of 2023 January 23 To January 29.pngWeek4of2023January23ToJanuary29
8Week Number2Week 2 of 2023 January 09 To January 15.png25Week 5 of 2023 January 30 To February 05.pngWeek5of2023January30ToFebruary05
9Start DateJanuary 0926Week 6 of 2023 February 06 To February 12.pngWeek6of2023February06ToFebruary12
10End DateJanuary 15Week 2 of 2023 January 09 To January 15.pngJanuary 09January 1527Week 7 of 2023 February 13 To February 19.pngWeek7of2023February13ToFebruary19
ForecastHistory2023
Cell Formulas
RangeFormula
B2:C2,E2C2=Forecast!E2
H2H2=IF(A3=$A$1,H1,H1+1)
B3B3=J1
E3,E7E3=B5
G3,G7G3=B6
H3,H7H3=B4
B4,B8B4=ISOWEEKNUM(C3)
C4,C8C4=C6
H4,H8H4=IF(A3=$A$1,H3,H3)
B5,B9B5=MAX(DATE(B3,1,1),DATE(B3,1,1)-WEEKDAY(DATE(B3,1,1),2)+(B4)*7+1)
H5,H9H5=IF(A3=$A$1,H4,H4)
B6,B10B6=MIN(DATE(B3+1,1,0),DATE(B3,1,1)-WEEKDAY(DATE(B3,1,1),2)+(B4+1)*7)
C6,C10C6="Week "&B4&" of "&B3&" "&E6&" To "&G6&".png"
B7B7=J1
C7C7=C3+7
G6,G10G6=TEXT($B6,"mmmm dd")
H6,H10H6=IF(A3=$A$1,H5,H5)
E6,E10E6=TEXT($B5,"mmmm dd")
K4:K10K4=INDEX($C$3:$C$210,(ROW()-4)*4+4)


Cell Formulas
RangeFormula
B2:C2,E2C2=Forecast!E2
H2H2=IF(A3=$A$1,H1,H1+1)
B3B3=J1
E3,E11,E7E3=B5
G3,G11,G7G3=B6
H3,H11,H7H3=B4
B4,B12,B8B4=ISOWEEKNUM(C3)
C4,C12,C8C4=C6
H4,H12,H8H4=IF(A3=$A$1,H3,H3)
B5,B13B5=MAX(DATE(B3,1,1),DATE(B3,1,1)-WEEKDAY(DATE(B3,1,1),2)+(B4)*7+1)
H5,H13,H9H5=IF(A3=$A$1,H4,H4)
B6,B14,B10B6=MIN(DATE(B3+1,1,0),DATE(B3,1,1)-WEEKDAY(DATE(B3,1,1),2)+(B4+1)*7)
C6,C14,C10C6="Week "&B4&" of "&B3&" "&E6&" To "&G6&".png"
B7B7=J1
C7,C11C7=C3+7
G6,G14,G10G6=TEXT($B6,"mmmm dd")
H6,H14,H10H6=IF(A3=$A$1,H5,H5)
E6,E14,E10E6=TEXT($B5,"mmmm dd")
B9B9=MAX(DATE(B7,1,1),DATE(B7,1,1)-WEEKDAY(DATE(B7,1,1),2)+(B8)+7)
B11B11=J1
K4:K14K4=INDEX($C$3:$C$210,(ROW()-4)*4+4)
 

Excel Facts

Can a formula spear through sheets?
Use =SUM(January:December!E7) to sum E7 on all of the sheets from January through December
These modified formula will get the start/end date based upon year/week no.

Book1
ABC
1Year20232024
2Week Number11
3Start Date1/2/20231/1/2024
4End Date1/8/20231/7/2024
Sheet3
Cell Formulas
RangeFormula
B3:C3B3=DATE(B1,1,8)-WEEKDAY(DATE(B1,1,6))+(B2-1)*7
B4:C4B4=6+B3
 
Upvote 0
Awesome, thanks loads Alan. This did exactly what is needed.
On another note, how do I determine what version is my XL2BB?
 
Upvote 0
Alan, I figured out how to tell what version I have.
1637586473945.png
 
Upvote 0

Forum statistics

Threads
1,223,897
Messages
6,175,270
Members
452,628
Latest member
dd2

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