+ Reply to Thread
Results 1 to 7 of 7

CountIFS using an OR function

  1. #1
    Registered User
    Join Date
    08-09-2010
    Location
    Midlands
    MS-Off Ver
    Excel 2010
    Posts
    38

    CountIFS using an OR function

    Hi,

    I have tried searching the forums and google for an answer to do this but I cannot seem to find a solution to my problem.

    I am using Excel 2007 and looking at a large amount of data. To simplify the problem I have built the Table below
    A B
    1 Jack
    1 James
    2 John
    2 jack
    2 james
    1 james

    I want to use Countifs to display the amount of times that Jack OR James are displayed in B AND 1 is displayed in Column 1.

    I have tried to do this through, = countifs($A:$A, "=1", $B:$B, {"Jack", "James"})
    however the result it returns only reviews the first in the array, in this case, Jack.

    Is there any way to use a nested OR function within a Countifs function without having to create a separate column and using =if(OR(A1="Jack", A1="James"),1,0) and then using Countifs with =countifs($A:$A, "=1", $C:$C,1) as the data set I am using is very large and this would be very time consuming.

    Any / all help would be appreciated!

    Many thanks

    Maudise
    Last edited by Maudise; 08-09-2010 at 11:03 AM.

  2. #2
    Forum Expert NBVC's Avatar
    Join Date
    12-06-2006
    Location
    Mississauga, CANADA
    MS-Off Ver
    2003:2010
    Posts
    34,898

    Re: CountIFS using an OR function

    COUNTIFS is by nature an AND construct...

    To do an OR...use Sumproduct

    e.g.
    =SUMPRODUCT(((A1:A100="JACK")+(A1:A100="James"))*(C1:C100=1))

    or

    =SUMPRODUCT((A1:A100={"JACK","James"})*(C1:C100=1))

    or add 2 individual Countifs() together

    =COUNTIFS(A1:A100,"Jack",C1:C100,1)+COUNTIFS(A1:A100,"James",C1:C100,1)

    or even:

    =SUM(COUNTIFS(A1:A100,{"Jack","James"},C1:C100,1))
    Last edited by NBVC; 08-09-2010 at 11:26 AM. Reason: typo
    Where there is a will there are many ways.

    If you are happy with the results, please add to the contributor's reputation by clicking the reputation icon (star icon) below left corner

    Please also mark the thread as Solved once it is solved. Check the FAQ's to see how.

  3. #3
    Forum Guru
    Join Date
    08-05-2004
    Location
    NJ
    MS-Off Ver
    365
    Posts
    13,582

    Re: CountIFS using an OR function

    SUMPRODUCT Should work for you. Try this;

    =SUMPRODUCT(--($A$1:$A$10=1),($B$1:$B$10="Jack")+($B$1:$B$10="John"))

    Does that work for you?
    ChemistB
    My 2?

    substitute commas with semi-colons if your region settings requires
    Don't forget to mark threads as "Solved" (Edit First post>Advanced>Change Prefix)
    If I helped, Don't forget to add to my reputation (click on the little star at bottom of this post)

    Forum Rules: How to use code tags, mark a thread solved, and keep yourself out of trouble

  4. #4
    Forum Contributor WinteE's Avatar
    Join Date
    04-07-2007
    Location
    Netherlands
    Posts
    544

    Re: CountIFS using an OR function

    Hi Maudise,

    You can do this by using =SUMPRODUCT()

    =SUMPRODUCT((A1:A6=E1)*(B1:B6=D1)*1), where cell E1 contains a number and cell D1 a name.

    Erik
    Just keep it simple !


    http://www.excelguide.eu
    In English as well as in Dutch

  5. #5
    Registered User
    Join Date
    08-09-2010
    Location
    Midlands
    MS-Off Ver
    Excel 2010
    Posts
    38

    Re: CountIFS using an OR function

    Hi All,

    Thanks for the prompt responses! The solutions do work, perhaps I over simplified it though. The countifs has several criteria attached and so was trying to keep the formula's down to a manageable size using arrays and a function. I have expanded it out just to see whether it can be adapted to be a little less unweidly, but I suspect further columns with sumproducts would be needed.

    I want to see where Name = {"Jack", "James"}, Date >= 5th Jan AND <=7th Jan, Type = "Normal"

    A B C D
    Date Name Outcome Type
    5th Jan Jack Success Normal
    6th Jan James Void Normal
    5th Jan Jack Success Normal
    5th Jan James Failure Normal
    6th Jan John Void Normal
    6th Jan John Success Normal
    7th Jan John Success Normal
    7th Jan Jack Success Non-Standard
    7th Jan Jack Failure Normal
    8th Jan James Failure Non-Standard


    The formula I am using at the minute is =countifs($A:$A, ">="&$E$2, $A:$A, "<"&$E$3, $C:$C, "<> Void",$D:$D, "=Normal", <PROBLEM OCCURS HERE> $B:$B, {"Jack", "James"})

    The array for Jack / James in practice can get to 10 or so different variations and the spreadsheet is very large. Is there any way of embedding them to amalgamate the OR and the AND functions to count or is it easiest to use the =if(or(B1="jack", B1="James"),1,0) and then adding in the extra column =1 function into the countifs.

    But thank you for the Sumproduct answers, they're really useful for something else I've been working on!

    Thanks
    Muaidse

  6. #6
    Forum Contributor WinteE's Avatar
    Join Date
    04-07-2007
    Location
    Netherlands
    Posts
    544

    Re: CountIFS using an OR function

    Have a look on my site and find out about MLOOKUP.

  7. #7
    Forum Guru DonkeyOte's Avatar
    Join Date
    10-22-2008
    Location
    Northumberland, UK
    MS-Off Ver
    O365
    Posts
    21,531

    Re: CountIFS using an OR function

    Quote Originally Posted by Maudise View Post
    I want to see where Name = {"Jack", "James"}, Date >= 5th Jan AND <=7th Jan, Type = "Normal"

    ...
    The formula I am using at the minute is

    =countifs($A:$A, ">="&$E$2, $A:$A, "<"&$E$3, $C:$C, "<> Void",$D:$D, "=Normal", <PROBLEM OCCURS HERE> $B:$B, {"Jack", "James"})

    The array for Jack / James in practice can get to 10 or so different variations and the spreadsheet is very large. Is there any way of embedding them to amalgamate the OR and the AND functions to count or is it easiest to use the =if(or(B1="jack", B1="James"),1,0) and then adding in the extra column =1 function into the countifs.
    As NBVC has already shown you can use an inline array for the OR terms and encase within a SUM

    Please Login or Register  to view this content.
    however you should note you are in effect performing multiple COUNTIFS and thus a single field denoting 1/0 would make sense - used in conjunction with a single COUNTIFS function (much more efficient than SUMPRODUCT).

    Quote Originally Posted by WinteE
    =SUMPRODUCT((A1:A6=E1)*(B1:B6=D1)*1)
    @Erik, the *1 is superfluous given the multiplication of the Logical Arrays is already coercing the output.

+ Reply to Thread

Thread Information

Users Browsing this Thread

There are currently 1 users browsing this thread. (0 members and 1 guests)

Bookmarks

Posting Permissions

  • You may not post new threads
  • You may not post replies
  • You may not post attachments
  • You may not edit your posts

Search Engine Friendly URLs by vBSEO 3.6.0 RC 1