Calculate sum based on date to show as this month

maybeso

New Member
Joined
Feb 25, 2022
Messages
2
Office Version
  1. 365
Platform
  1. Windows
Hi team, I want to have a rolling total of 'This month figures' and 'Next month figures' based on dates in one column and corresponding amounts. So in column B there is a date, Column C an amount. If the date is within 'this month' I want it to add the column C figure, same for next month. Basically I am looking to get expected figures for this month and next month displayed at the top of the spreadsheet, without having to change the formula each month. I hope that makes sense. Thankful for any guidance.
 

Excel Facts

What is =ROMAN(40) in Excel?
The Roman numeral for 40 is XL. Bill "MrExcel" Jelen's 40th book was called MrExcel XL.
for this month
=SUMIFS(C2:C11,B2:B11,">="&DATE(YEAR(TODAY()),MONTH(TODAY()),DAY(1)),B2:B11,"<="&EOMONTH(TODAY(),0))

next month
=SUMIFS(C2:C11,B2:B11,">="&DATE(YEAR(TODAY()),MONTH(TODAY())+1,DAY(1)),B2:B11,"<="&EOMONTH(TODAY(),1))

Various.xlsx
BCDEFG
1dateamountThis Monthnext Month
21/1/221120600
31/10/222
41/19/223
51/28/224
62/6/2220
72/15/2240
82/24/2260
93/5/22100
103/14/22200
113/23/22300
Sheet14
Cell Formulas
RangeFormula
F2F2=SUMIFS(C2:C11,B2:B11,">="&DATE(YEAR(TODAY()),MONTH(TODAY()),DAY(1)),B2:B11,"<="&EOMONTH(TODAY(),0))
G2G2=SUMIFS(C2:C11,B2:B11,">="&DATE(YEAR(TODAY()),MONTH(TODAY())+1,DAY(1)),B2:B11,"<="&EOMONTH(TODAY(),1))
 
Upvote 0
Solution
for this month
=SUMIFS(C2:C11,B2:B11,">="&DATE(YEAR(TODAY()),MONTH(TODAY()),DAY(1)),B2:B11,"<="&EOMONTH(TODAY(),0))

next month
=SUMIFS(C2:C11,B2:B11,">="&DATE(YEAR(TODAY()),MONTH(TODAY())+1,DAY(1)),B2:B11,"<="&EOMONTH(TODAY(),1))

Various.xlsx
BCDEFG
1dateamountThis Monthnext Month
21/1/221120600
31/10/222
41/19/223
51/28/224
62/6/2220
72/15/2240
82/24/2260
93/5/22100
103/14/22200
113/23/22300
Sheet14
Cell Formulas
RangeFormula
F2F2=SUMIFS(C2:C11,B2:B11,">="&DATE(YEAR(TODAY()),MONTH(TODAY()),DAY(1)),B2:B11,"<="&EOMONTH(TODAY(),0))
G2G2=SUMIFS(C2:C11,B2:B11,">="&DATE(YEAR(TODAY()),MONTH(TODAY())+1,DAY(1)),B2:B11,"<="&EOMONTH(TODAY(),1))
Thank you so much, this is awesome!! Worked perfectly!
 
Upvote 0

Forum statistics

Threads
1,214,998
Messages
6,122,639
Members
449,093
Latest member
Ahmad123098

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