Adjust date range year

bademployee

Board Regular
Joined
Aug 19, 2010
Messages
184
Hi all

Have been using:

Code:
=SUM(Journal!$BY$9:$BY$504)-(SUMIF(Journal!$J$9:$J$504,">31/01/2014",Journal!$BY$9:$BY$504)+SUMIF(Journal!$J$9:$J$504,""<1/1/"2014",Journal!$BY$9:$BY$504))

I have to remember to change the year each year....any ideas how to overcome this?

The user inputs the year in "Journal!V4" on another sheet if it's of any help.

Thanks for any help in advance.

Mark
 

Excel Facts

Shade all formula cells
To shade all formula cells: Home, Find & Select, Formulas to select all formulas. Then apply a light fill color.

maheshmaxi

Active Member
Joined
Dec 16, 2008
Messages
252
Which date range do you need to exclude whether from 1st Jan '14 to 31st Jan '14? Can you pls make it clear pls?
 

Peter_SSs

MrExcel MVP, Moderator
Joined
May 28, 2005
Messages
54,272
Office Version
  1. 365
Platform
  1. Windows
Try

=SUM(Journal!$BY$9:$BY$504)-(SUMIF(Journal!$J$9:$J$504,">"&DATE(Journal!V4,1,31),Journal!$BY$9:$BY$504)+SUMIF(Journal!$J$9:$J$504,"<"&DATE(Journal!V4,1,1),Journal!$BY$9:$BY$504))

But you could also try the following alternatives, the first of which requires Excel 2007 or later.

=SUMIFS(Journal!$BY$9:$BY$504,Journal!$J$9:$J$504,">="&DATE(Journal!V4,1,1),Journal!$J$9:$J$504,"<="&DATE(Journal!V4,1,31))

=SUMPRODUCT(--(TEXT(Journal!$J$9:$J$504,"mmm-yyyy")="Jan-"&Journal!V4),Journal!$BY$9:$BY$504)
 

bademployee

Board Regular
Joined
Aug 19, 2010
Messages
184
Try

=SUM(Journal!$BY$9:$BY$504)-(SUMIF(Journal!$J$9:$J$504,">"&DATE(Journal!V4,1,31),Journal!$BY$9:$BY$504)+SUMIF(Journal!$J$9:$J$504,"<"&DATE(Journal!V4,1,1),Journal!$BY$9:$BY$504))

But you could also try the following alternatives, the first of which requires Excel 2007 or later.

=SUMIFS(Journal!$BY$9:$BY$504,Journal!$J$9:$J$504,">="&DATE(Journal!V4,1,1),Journal!$J$9:$J$504,"<="&DATE(Journal!V4,1,31))

=SUMPRODUCT(--(TEXT(Journal!$J$9:$J$504,"mmm-yyyy")="Jan-"&Journal!V4),Journal!$BY$9:$BY$504)

Wow!......certainly know your way around a spreadsheet ;)

Thanks Peter, the third option was perfect.

Appreciate your help

Mark
 
Master Excel Bundle

Excel contains over 450 functions, with more added every year. That’s a huge number, so where should you start? Right here with this bundle.

Forum statistics

Threads
1,163,598
Messages
5,832,646
Members
430,150
Latest member
amitk1

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
Top