Making the formula Dynamic based on Date Range

apie5

New Member
Joined
Jun 27, 2018
Messages
6
Hi All -- I was hoping you can help me make the following formula dynamic based on a date range..

I have this formula : =INDEX(LINEST(I62:I73,J62:J73),2)*12

[FONT=&quot]I have a table of dates (end of month dates) and two columns with numbers which I need summed up based on the most recent 12 months. The date set dates back to 2014 and goes all the way to 9/30/2019. I need to be able to be calculate the data from 10/31/2018 - 9/30/2019.. I want my formula to be dynamic, so next month I would like to have the data set calculate the months of 11/30/2018 - 10/31/2019. Here is a sample set of my data table, data was removed for columns that are irrelevant. Is there a way to make the above formula dynamic based on the most recent month end going back 12 months?

[/FONT]
thanks!

[FONT=&quot][/FONT]
12/30/201600000000.0242916670.018987
1/31/201700000000.0220416670.018284
2/28/201700000000.0467916670.038542
3/31/201700000000.0016750.000375
4/28/201700000000.0165916670.009308
5/31/201700000000.016250.012773
6/30/20170000000-0.0074083330.005105
7/31/201700000000.0213166670.019516
8/31/201700000000.0086833330.00149
9/29/201700000000.0156250.019455
10/31/201700000000.0220166670.022207
11/30/201700000000.0303733330.029077
12/29/201700000000.0105366670.009798
1/31/201800000000.0643683330.05589
2/28/20180000000-0.048175-0.03866
3/29/20180000000-0.029423333-0.02709
4/30/201800000000.0029966670.002169
5/31/201800000000.0304766670.022007
6/29/201800000000.0110883330.004318
7/31/201800000000.0392383330.035414
8/31/201800000000.0320883330.030296
9/28/201800000000.0053983330.003681
10/31/20180000000-0.071401667-0.07041
11/30/201800000000.020.017823
12/31/20180000000-0.086621667-0.09263
1/31/201900000000.092340.077703
2/28/201900000000.0320466670.02941
3/29/201900000000.019030.016978
4/30/201900000000.0378983330.038147
5/31/20190000000-0.069383333-0.0662
6/28/201900000000.0656450.068085
7/31/201900000000.0150766670.012217
8/30/20190000000-0.024263333-0.01815
9/30/201900000000.0162533330.016534

<colgroup><col><col span="7"><col><col></colgroup><tbody>
</tbody>
 

Excel Facts

Remove leading & trailing spaces
Save as CSV to remove all leading and trailing spaces. It is faster than using TRIM().
Possibly:

Code:
=INDEX(LINEST(OFFSET(I1:I12,MATCH(EOMONTH(TODAY(),-12),A1:A1000,0)-1,0),OFFSET(J1:J12,MATCH(EOMONTH(TODAY(),-12),A1:A1000,0)-1,0)),2)*12
Longer, but non-volatile:

Code:
=INDEX(LINEST(INDEX(I:I,MATCH(EOMONTH(TODAY(),-12),A1:A1000,0)):INDEX(I:I,MATCH(EOMONTH(TODAY(),-1),A1:A1000,0)),INDEX(J:J,MATCH(EOMONTH(TODAY(),-12),A1:A1000,0)):INDEX(J:J,MATCH(EOMONTH(TODAY(),-1),A1:A1000,0))),2)*12
 
Upvote 0
Possibly:

Code:
=INDEX(LINEST(OFFSET(I1:I12,MATCH(EOMONTH(TODAY(),-12),A1:A1000,0)-1,0),OFFSET(J1:J12,MATCH(EOMONTH(TODAY(),-12),A1:A1000,0)-1,0)),2)*12
Longer, but non-volatile:

Code:
=INDEX(LINEST(INDEX(I:I,MATCH(EOMONTH(TODAY(),-12),A1:A1000,0)):INDEX(I:I,MATCH(EOMONTH(TODAY(),-1),A1:A1000,0)),INDEX(J:J,MATCH(EOMONTH(TODAY(),-12),A1:A1000,0)):INDEX(J:J,MATCH(EOMONTH(TODAY(),-1),A1:A1000,0))),2)*12


I used the second one and it worked like a charm!! Thank you so much!
 
Upvote 0
Hi Eric -- Is there a way to make this formula do the same? Same deal as above. I want to calculate dynamically based on the most recent date and go back twelve months.. thanks!

=(12*AVERAGE(I62:I7300))/(SQRT(12)*STDEV.S(I62:I7300))
 
Upvote 0
Sure, same idea:

Code:
=(12*AVERAGE(INDEX(I:I,MATCH(EOMONTH(TODAY(),-12),A1:A7300,0)):INDEX(I:I,MATCH(EOMONTH(TODAY(),-1),A1:A7300,0))))/(SQRT(12)*STDEV.S(INDEX(I:I,MATCH(EOMONTH(TODAY(),-12),A1:A7300,0)):INDEX(I:I,MATCH(EOMONTH(TODAY(),-1),A1:A7300,0))))
 
Upvote 0
Sure, same idea:

Code:
=(12*AVERAGE(INDEX(I:I,MATCH(EOMONTH(TODAY(),-12),A1:A7300,0)):INDEX(I:I,MATCH(EOMONTH(TODAY(),-1),A1:A7300,0))))/(SQRT(12)*STDEV.S(INDEX(I:I,MATCH(EOMONTH(TODAY(),-12),A1:A7300,0)):INDEX(I:I,MATCH(EOMONTH(TODAY(),-1),A1:A7300,0))))


Thank you so much!!! Have a wonderful weekend!
 
Upvote 0

Forum statistics

Threads
1,213,520
Messages
6,114,099
Members
448,548
Latest member
harryls

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