+ Reply to Thread
Results 1 to 3 of 3

countif/sumproduct on multiple criteria

  1. #1
    Phil.M
    Guest

    countif/sumproduct on multiple criteria

    looking for help with following

    a1 b1 c1
    x r m
    x s m
    t r m
    x r d
    y r m

    The problem is I want to count the occurences of m
    if (a1 = x and b1 = r) and if (a1 = y and b1 =r)
    the solution I am looking for is ( 2 in the above table)
    I have about 500 lines of data to process
    * note ( range of a1 cell are merged ,ie: a1+a2 a3+a4 ect..)

    any solution would be helpful.


  2. #2
    JulieD
    Guest

    Re: countif/sumproduct on multiple criteria

    Hi Phil

    bit confused on the merging comment
    do you have
    .........A............B...............C
    1....x..............r..................m
    2....................s..................m
    3....t...............r...................m
    4...................r......................d

    where A1 & A2, A3 & A4 are merged but columns B & C aren't ... in this case
    i'm confused as to how A3 has t and A4 has x as per your example ..... and
    i'm not sure an answer is easily possible

    if the cells aren't merged then the formula would simply be along the lines
    of
    =SUMPRODUCT(--(A8:A12="x"),--(B8:B12="r"),--(C8:C12="m"))
    this formula would work in A1&A2, B1 & B2, C1&C2 are merged but not if
    A1&A2 are merged and B1, B2, C1, C2 aren't

    --
    Cheers
    JulieD
    check out www.hcts.net.au/tipsandtricks.htm
    ....well i'm working on it anyway
    "Phil.M" <[email protected]> wrote in message
    news:[email protected]...
    > looking for help with following
    >
    > a1 b1 c1
    > x r m
    > x s m
    > t r m
    > x r d
    > y r m
    >
    > The problem is I want to count the occurences of m
    > if (a1 = x and b1 = r) and if (a1 = y and b1 =r)
    > the solution I am looking for is ( 2 in the above table)
    > I have about 500 lines of data to process
    > * note ( range of a1 cell are merged ,ie: a1+a2 a3+a4 ect..)
    >
    > any solution would be helpful.
    >




  3. #3
    Peo Sjoblom
    Guest

    Re: countif/sumproduct on multiple criteria

    =SUMPRODUCT(--((A2:A10="x")+(A2:A10="y")>0),--(B2:B10="r"),--(C2:C10="m"))

    or


    =SUMPRODUCT((A2:A10={"x","y"})*(B2:B10="r")*(C2:C10="m"))

    I don't know what you mean by merged, if indeed you mean merged as in
    format>cells>alignment and merge? If so unmerge the cells, remember nothing
    good comes from merging cells

    --
    Regards,

    Peo Sjoblom


    "Phil.M" <[email protected]> wrote in message
    news:[email protected]...
    > looking for help with following
    >
    > a1 b1 c1
    > x r m
    > x s m
    > t r m
    > x r d
    > y r m
    >
    > The problem is I want to count the occurences of m
    > if (a1 = x and b1 = r) and if (a1 = y and b1 =r)
    > the solution I am looking for is ( 2 in the above table)
    > I have about 500 lines of data to process
    > * note ( range of a1 cell are merged ,ie: a1+a2 a3+a4 ect..)
    >
    > any solution would be helpful.
    >




+ 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