Help with formula to sum numbers prior to date

ExcelAtEverything

Active Member
Joined
Jan 30, 2021
Messages
351
Office Version
  1. 2019
Platform
  1. Windows
Hello,

I was hoping to get some assistance as I'm having trouble with this. Using my table below as an example, how could I write a formula which will basically say:

* For each store, add all monthly dollar amounts for months that occur prior to the month of the "Reporting Date" in $B$2. (or in this case, Jan & Feb)

*For the month in the table which is equal to the "Reporting Date" in $B$2 (in this case, March), I would like to take the daily average of the dollar amount shown for that month (divided evenly by # days in that month (in this case 31)), and multiply by the number of days that have passed so far in the "Reporting Date" $B$2 (specifically up to but not including the "Reporting Date"). In other words using the displayed table, for the month of March (since that's a partial month due to the "Reporting Date"), Instead of entering $100, I would only enter $87.21 (since that is an estimated amount based on the "Reporting Date".

Thank you.

1617963238870.png
 

Excel Facts

Move date out one month or year
Use =EDATE(A2,1) for one month later. Use EDATE(A2,12) for one year later.
@ExcelAtEverything Maybe something like.....

Book1
BCDEFGHIJKLMNOP
228/03/2021
3
4To DateJanFebMarAprMayJunJulAugSepOctNovDecTotal
5337.10Loc11001501001501501601701801902002102201980
6624.19Loc22002502002502602702802903003103203303260
Sheet1
Cell Formulas
RangeFormula
D4:O4D4=EOMONTH("01/01/2021",COLUMNS($D:D)-1)
B5:B6B5=SUMIF($D$4:$O$4,"<"&$B$2,D5:O5)+INDEX(D5:O5,MONTH($B$2))*(DAY($B$2)-1)/DAY(EOMONTH($B$2,0))
P5:P6P5=SUM(D5:O5)


Note the formulas in D4:O4. (D4 and drag across) would need updating each year to account for a leap year.

Hope that helps.
 
Upvote 0
=SUMIF($D$4:$O$4,"<"&$B$2,D5:O5)+INDEX(D5:O5,MONTH($B$2))*(DAY($B$2)-1)/DAY(EOMONTH($B$2,0))
Thanks Snakehips! That seems to only work for this one instance. In other words if I change the date to anything other than 3/28/21, it gives incorrect results. Below are two examples. Look at reporting date, and then see results in column R. And here is the formula I used:
=SUMIF($D$4:$O$4,"<"&$B$2,$D5:$O5)+INDEX($D5:$O5,MONTH($B$2))*(DAY($B$2)-1)/DAY(EOMONTH($B$2,0))

1617975632389.png

1617975311415.png
 
Upvote 0
It works for me.

Book1
BCDEFGHIJKLMNOP
201/03/2021
3
4To DateJanFebMarAprMayJunJulAugSepOctNovDecTotal
5250.00Loc11001501001501501601701801902002102201980
6450.00Loc22002502002502602702802903003103203303260
Sheet1
Cell Formulas
RangeFormula
D4:O4D4=EOMONTH("01/01/2021",COLUMNS($D:D)-1)
B5:B6B5=SUMIF($D$4:$O$4,"<"&$B$2,D5:O5)+INDEX(D5:O5,MONTH($B$2))*(DAY($B$2)-1)/DAY(EOMONTH($B$2,0))
P5:P6P5=SUM(D5:O5)


I see you have US style date but that shouldn't be an issue.
Please report back.
I'm out for an hour now.
 
Upvote 0
Are your headers text or dates?
 
Upvote 0
Hi Fluff! Headers were formatted as General, but I just switched to Custom "mmm" and no change in result.
 
Upvote 0
Changing the format does not change the underlying value.
Do you have dates in those cells or text (eg Jan Feb etc)?
 
Upvote 0
In that case change them to dates using the 1st of the month.
 
Upvote 0

Forum statistics

Threads
1,213,543
Messages
6,114,236
Members
448,555
Latest member
RobertJones1986

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