Multiple conditions based on end of month

Binghamcornwall

New Member
Joined
Aug 21, 2008
Messages
13
I have a spreadsheet 'Log' that contains an eomonth formula '=EOMONTH(A4,0)', formatted to custom mmm-yy On a separate sheet I am trying to collate stats on the number of times two conditions are met, one of which is based on the end of month mentioned above.

The formula I am using is '{=SUM((Log!C4:C134="New")*(Log!X4:X134="May-10"))}, using control, shift and enter to enter the formula to establish {}.

The formula is consistently returning zero, when I know it should have a total. I am assuming the problem lies with the eomonth format. Can anyone help?

The solution may be simple, but I appear to be missing it. Many thanks.
 

Some videos you may like

Excel Facts

Spell Check in Excel
Press F7 to start spell check in Excel. Be careful, by default, Excel does not check Capitalized Werds (whoops)

xld

Banned
Joined
Feb 8, 2003
Messages
5,378
The format is irrelevant. Try

=SUM((Log!C4:C134="New")*(Log!X4:X134=--"31-May-10"))
 

AlphaFrog

MrExcel MVP
Joined
Sep 2, 2009
Messages
16,381
"May-10" is a text string and not an actual date.

Try something like this...
{=SUM((Log!C4:C134="New")*(Log!X4:X134=DATE(2010,5,31)))}

Or this
{=SUM((Log!C4:C134="New")*(Log!X4:X134=DATEVALUE("May 31, 2010")))}
 

njimack

Well-known Member
Joined
Jun 17, 2005
Messages
7,764
The formatting doesn't change the fact that your EOMONTH formula is actually returning a date. Try the following (non-array) approach:

=SUMPRODUCT(--(Log!C4:C134="New"),--(MONTH(Log!X4:X134)=MONTH(A4)),--(YEAR(Log!X4:X134)=YEAR(A4))
 

Binghamcornwall

New Member
Joined
Aug 21, 2008
Messages
13
Many thanks.

The formula that worked was =SUM((Log!C4:C134="New")*(Log!X4:X134=DATEVALUE("31 May 2010"))) entered as an array formula.

I missed the fact that May-10 was a text string, another lesson learnt!

Again many thanks for the help, it is much appreciated.

;)
 

Watch MrExcel Video

Forum statistics

Threads
1,122,710
Messages
5,597,702
Members
414,164
Latest member
ARTW

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