+ Reply to Thread
Results 1 to 8 of 8

Can I use more complex logical expression for sumif as creteria?

Hybrid View

  1. #1
    xwenx
    Guest

    Can I use more complex logical expression for sumif as creteria?

    I want to use a more complex logical expression as creteria in SUMIF. For
    example, sum number in the cell on column 6 when cell on column 1 is "MA" AND
    cell on column 2 is greater than 5000. I may use either "and" or "or" to
    connect the two tests. Is there an easy way to do that without creating an
    extra combined column (to make MA5001, MA12400, NH2300, etc.)


  2. #2
    Mark Lincoln
    Guest

    Re: Can I use more complex logical expression for sumif as creteria?

    You can use SUMPRODUCT like this:

    =SUMPRODUCT(--(A3:A10="MA"),--(B3:B10>5000),F3:F10)

    Your state abbreviations are in A3:A10, your numbers to test on are in
    B3:B10, and the numbers to sum are in F3:F10 (column 6). Change to
    suit your circumstance.


  3. #3
    xwenx
    Guest

    Re: Can I use more complex logical expression for sumif as creteri

    Thank you, Mark.
    What if the condition is an "or" (not and). Either the first or the second
    condition is met, then do the sum up...

    "Mark Lincoln" wrote:

    > You can use SUMPRODUCT like this:
    >
    > =SUMPRODUCT(--(A3:A10="MA"),--(B3:B10>5000),F3:F10)
    >
    > Your state abbreviations are in A3:A10, your numbers to test on are in
    > B3:B10, and the numbers to sum are in F3:F10 (column 6). Change to
    > suit your circumstance.
    >
    >


  4. #4
    Mark Lincoln
    Guest

    Re: Can I use more complex logical expression for sumif as creteri

    That complicates matters some. We have to sum the rows in which either
    criterion is met and subtract the rows where both are met (otherwise
    the latter cases would be counted twice). Either of these work:

    =SUMPRODUCT(--(A3:A10="MA"),F3:F10)+SUMPRODUCT(--(B3:B10>5000),F3:F10)-SUMPRODUCT(--(A3:A10="MA"),--(B3:B10>5000),F3:F10)

    =SUMIF(A3:A10,"MA",F3:F10)+SUMIF(B3:B10,">5000",F3:F10)-SUMPRODUCT(--(A3:A10="MA"),--(B3:B10>5000),F3:F10)


  5. #5
    JE McGimpsey
    Guest

    Re: Can I use more complex logical expression for sumif as creteri

    This is a bit shorter:

    =SUMPRODUCT(--((A3:A10="MA")+(B3:B10>5000)>0),F3:F10)


    In article <1146163561.677247.234460@u72g2000cwu.googlegroups.com>,
    "Mark Lincoln" <mlincoln@earthlink.net> wrote:

    > That complicates matters some. We have to sum the rows in which either
    > criterion is met and subtract the rows where both are met (otherwise
    > the latter cases would be counted twice). Either of these work:
    >
    > =SUMPRODUCT(--(A3:A10="MA"),F3:F10)+SUMPRODUCT(--(B3:B10>5000),F3:F10)-SUMPROD
    > UCT(--(A3:A10="MA"),--(B3:B10>5000),F3:F10)
    >
    > =SUMIF(A3:A10,"MA",F3:F10)+SUMIF(B3:B10,">5000",F3:F10)-SUMPRODUCT(--(A3:A10="
    > MA"),--(B3:B10>5000),F3:F10)


  6. #6
    JE McGimpsey
    Guest

    Re: Can I use more complex logical expression for sumif as creteri

    Oops, didn't see the identical solution in the other subthread...

    In article <jemcgimpsey-5E3D43.17503727042006@msnews.microsoft.com>,
    JE McGimpsey <jemcgimpsey@mvps.org> wrote:

    > This is a bit shorter:
    >
    > =SUMPRODUCT(--((A3:A10="MA")+(B3:B10>5000)>0),F3:F10)
    >


  7. #7
    Biff
    Guest

    Re: Can I use more complex logical expression for sumif as creteri

    Hi!

    Try this (using Marks example):

    =SUMPRODUCT(--((A3:A10="MA")+(B3:B10>5000)>0),F3:F10)

    Biff

    "xwenx" <xwenx@discussions.microsoft.com> wrote in message
    news:80FC0DBA-045A-4CB3-BD39-AADEB3939C4D@microsoft.com...
    > Thank you, Mark.
    > What if the condition is an "or" (not and). Either the first or the second
    > condition is met, then do the sum up...
    >
    > "Mark Lincoln" wrote:
    >
    >> You can use SUMPRODUCT like this:
    >>
    >> =SUMPRODUCT(--(A3:A10="MA"),--(B3:B10>5000),F3:F10)
    >>
    >> Your state abbreviations are in A3:A10, your numbers to test on are in
    >> B3:B10, and the numbers to sum are in F3:F10 (column 6). Change to
    >> suit your circumstance.
    >>
    >>




  8. #8
    Mark Lincoln
    Guest

    Re: Can I use more complex logical expression for sumif as creteri

    Good solution, Biff. Nice and neat!

    I was trying something similar but got a #VALUE error. Then my
    solutions suggested themselves to me and in the interests of time (I do
    this during slack moments at work) I dropped my original effort.

    Three solutions to one problem. That's why I like this newsgroup. :-)


+ 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