• Hi All

    Please note that at the Chandoo.org Forums there is Zero Tolerance to Spam

    Post Spam and you Will Be Deleted as a User

    Hui...

  • When starting a new post, to receive a quicker and more targeted answer, Please include a sample file in the initial post.

SUMIFS (not working) vs SUMPRODUCT (working)

mxk

New Member
Dear all,


I am new to SUMPRODUCT and am still getting used to all it's power, so for the simple example below, I'd prefer to use SUMIFS if I can, instead of SUMPRODUCT, but it doesn't appear to work.


Can anyone help me out as to why SUMPRODUCT seems to work but SUMIFS doesn't in the example below? To me, they're should both return the same result - (ie 15)


Criteria 1 (A1) = 8

Criteria 2 (B1) = 1

Criteria 3 (C1) = Dec-10


A B C D

8 1 20/12/2010 10

8 1 9/12/2010 5

8 1 5/12/2008 2

8 4 7/12/2010 4

9 1 13/10/2010 9


=SUMPRODUCT((A4:A8=A1)*(B4:B8=B1)*(MONTH(C4:C8)=MONTH(C1))*(YEAR(C4:C8)=YEAR(C1))*(D4:D8))

>> correctly gives 15


=SUMIFS(D4:D8,A4:A8,A1,B4:B8,B1,MONTH(C4:C8),MONTH(C1),YEAR(C4:C8),YEAR(C1))

>> doesn't work


I'm missing something obvious, aren't I?
 
Hi, mxk!


First of all welcome to Chandoo's website Excel forums. Thank you for your joining us and glad to have you here.


As a starting point I'd recommend you to read the three first green sticky topics at this forums main page. There you'll find general guidelines about how this site and community operates (introducing yourself, posting files, netiquette rules, and so on).


Among them you're prompted to perform searches within this site before posting, because maybe your question had been answered yet.


Feel free to play with different keywords so as to be led thru a wide variety of articles and posts, and if you don't find anything that solves your problem or guides you towards a solution, you'll always be welcome back here. Tell us what you've done, consider uploading a sample file as recommended, and somebody surely will read your post and help you.


And about your question...


SUMPRODUCT function works either with ranges or arrays and SUMIFS function does only with ranges, that's why it fails to handle arrays MONTH(C4:C8) and YEAR(C4:C8).


Regards!


EDIT: I now remember that Hui once talked about this (yes, everybody will say "what in Excel haven't talked Hui about?"), and I found it, here it is:

http://chandoo.org/forums/topic/quesion-regarding-sumifs-vs-sumproduct
 
Hello mxk,


Since you are looking to SUM for a month entered in C1, use 2 additional conditions like


C4:C8, >= First_Day_in_C1, C4:C8,<= Last_Day_in_C1


=SUMIFS(D4:D8,A4:A8,A1,B4:B8,B1,C4:C8,">="&EOMONTH(C1,-1)+1,C4:C8,"<="&EOMONTH(C1,0))


EOMONTH(C1,-1)+1 will give first day of month entered in C1

EOMONTH(C1,0) will give last day of month entered in C1


Make sure in C1 enter a valid date & format as you wish to display
 
SirJB7 - thank you so much for such a lovely, warm welcome. It's great to be on board!

3 x green sticky topics now read and Intro Post now posted - thanks :)

Thanks for your response - followed through on all the links as well and am now all good and up to speed..and also less afraid of SUMPRODUCT! Thank you.


Haseeb A - Awesome alternative. Love it - thanks, it's going in!
 
Hi, mxk!

Glad if it helped you. Thanks for your feedback and for your kind words too. Welcome back whenever needed or wanted.

Regards!
 
Back
Top