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
 

Some videos you may like

Excel Facts

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

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
46,165
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
 

Watch MrExcel Video

Forum statistics

Threads
1,108,614
Messages
5,523,906
Members
409,542
Latest member
Shezz01

This Week's Hot Topics

Top