+ Reply to Thread
Results 1 to 9 of 9

count unique with conditions

  1. #1
    \ditzman via OfficeKB.com\
    Guest

    count unique with conditions

    I am looking for a function or group of functions that can help me count the
    unique entries that meet two other criteria. The table is similar to:

    Column A: Column B: Column C: Column D:
    12346 Level1 ACME 345334
    12346 Level1 ACME 34523
    12346 Level2 ACME 34622
    12376 Level2 ACME 3453
    13255 Level2 DODAD 345
    13548 Level1 THINGABOB 322562
    12356 Level1 WIDGET 34622
    12376 Level2 WIDGET 3453
    12378 Level3 WIDGET 546443

    Column A is a list of unknown ID numbers. Column B&C values are known. The
    table is sorted by Column C, then Column B, then Column A, all in acending
    order. What I want is to be able to look for a value in Column C & Column B,
    and then count the unique items in Column A that matches with Column B & C.

    Example:
    If I search for "ACME" & "LEVEL1" I should get a result of 1.
    If I search for "ACME" & "LEVEL2" I should get a result of 2.

    I do not need to know which ones are unique, I just need to know the total of
    unique items as long as the line meets the other two criteria. I'm not sure
    if this is even possible. I'm using Excel 2000.

    Thanks for any help you can give me!!

    --
    Message posted via http://www.officekb.com

  2. #2
    Domenic
    Guest

    Re: count unique with conditions

    Try...

    =SUM(IF(FREQUENCY(IF((B1:B9="Level1")*(C1:C9="Acme"),A1:A9),IF((B1:B9="Le
    vel1")*(C1:C9="Acme"),A1:A9))>0,1,0))

    or

    =COUNT(1/FREQUENCY(IF((B1:B9="Level1")*(C1:C9="Acme"),A1:A9),IF((B1:B9="L
    evel1")*(C1:C9="Acme"),A1:A9)))

    Both these formulas need to be confirmed with CONTROL+SHIFT+ENTER, not
    just ENTER.

    Hope this helps!

    In article <[email protected]>,
    \"ditzman via OfficeKB.com\" <[email protected]> wrote:

    > I am looking for a function or group of functions that can help me count the
    > unique entries that meet two other criteria. The table is similar to:
    >
    > Column A: Column B: Column C: Column D:
    > 12346 Level1 ACME 345334
    > 12346 Level1 ACME 34523
    > 12346 Level2 ACME 34622
    > 12376 Level2 ACME 3453
    > 13255 Level2 DODAD 345
    > 13548 Level1 THINGABOB 322562
    > 12356 Level1 WIDGET 34622
    > 12376 Level2 WIDGET 3453
    > 12378 Level3 WIDGET 546443
    >
    > Column A is a list of unknown ID numbers. Column B&C values are known. The
    > table is sorted by Column C, then Column B, then Column A, all in acending
    > order. What I want is to be able to look for a value in Column C & Column B,
    > and then count the unique items in Column A that matches with Column B & C.
    >
    > Example:
    > If I search for "ACME" & "LEVEL1" I should get a result of 1.
    > If I search for "ACME" & "LEVEL2" I should get a result of 2.
    >
    > I do not need to know which ones are unique, I just need to know the total of
    > unique items as long as the line meets the other two criteria. I'm not sure
    > if this is even possible. I'm using Excel 2000.
    >
    > Thanks for any help you can give me!!


  3. #3
    \ditzman via OfficeKB.com\
    Guest

    Re: count unique with conditions

    Thanks! I believe it is working perfectly.

    --
    Message posted via http://www.officekb.com

  4. #4
    \ditzman via OfficeKB.com\
    Guest

    Re: count unique with conditions

    I have one more question. If Column B was slightly modified:

    Column A: Column B: Column C: Column D:
    12346 Level1a ACME 345334
    12346 Level1b ACME 34523
    12346 Level2 ACME 34622
    12376 Level2 ACME 3453
    13255 Level2 DODAD 345
    13548 Level1a THINGABOB 322562
    12356 Level1b WIDGET 34622
    12376 Level2 WIDGET 3453
    12378 Level3 WIDGET 546443

    Is there a way to do the same thing, but treat Level1a and Level1b as the
    same? So I can search for Acme, and Level1a and Level1b and still come up
    with a result of 1? I tried using "Level1*" in my function but it does not
    like that.

    Thanks again!

    --
    Message posted via http://www.officekb.com

  5. #5
    Domenic
    Guest

    Re: count unique with conditions

    Try...

    =SUM(IF(FREQUENCY(IF((LEFT(B1:B9,6)="Level1")*(C1:C9="Acme"),A1:A9),IF((L
    EFT(B1:B9,6)="Level1")*(C1:C9="Acme"),A1:A9))>0,1,0))

    or

    =COUNT(1/FREQUENCY(IF((LEFT(B1:B9,6)="Level1")*(C1:C9="Acme"),A1:A9),IF((
    LEFT(B1:B9,6)="Level1")*(C1:C9="Acme"),A1:A9)))

    Both formulas need to be confirmed with CONTROL+SHIFT+ENTER.

    Hope this helps!

    In article <[email protected]>,
    \"ditzman via OfficeKB.com\" <[email protected]> wrote:

    > I have one more question. If Column B was slightly modified:
    >
    > Column A: Column B: Column C: Column D:
    > 12346 Level1a ACME 345334
    > 12346 Level1b ACME 34523
    > 12346 Level2 ACME 34622
    > 12376 Level2 ACME 3453
    > 13255 Level2 DODAD 345
    > 13548 Level1a THINGABOB 322562
    > 12356 Level1b WIDGET 34622
    > 12376 Level2 WIDGET 3453
    > 12378 Level3 WIDGET 546443
    >
    > Is there a way to do the same thing, but treat Level1a and Level1b as the
    > same? So I can search for Acme, and Level1a and Level1b and still come up
    > with a result of 1? I tried using "Level1*" in my function but it does not
    > like that.
    >
    > Thanks again!


  6. #6
    \ditzman via OfficeKB.com\
    Guest

    Re: count unique with conditions

    That did it. Thanks again Domenic! It works great!

    --
    Message posted via http://www.officekb.com

  7. #7
    Registered User
    Join Date
    10-09-2003
    Posts
    25
    I have the similar situation except that Col A is not number but text. Tried both formulas (the ones without the LEFT function) but they returned 0 if Col A is text (not number). Can anyone help to advise how to amend the formula for this case. Thanks


    Column A: Column B: Column C: Column D:
    AP1 Level1a ACME 345334
    AP1 Level1b ACME 34523
    AP1 Level2 ACME 34622
    AP2 Level2 ACME 3453
    AP4 Level2 DODAD 345
    AP3 Level1a THINGABOB 322562
    AP5 Level1b WIDGET 34622
    AP2 Level2 WIDGET 3453
    AP6 Level3 WIDGET 546443

  8. #8
    Forum Expert
    Join Date
    06-18-2004
    Location
    Canada
    MS-Off Ver
    Office 2016
    Posts
    1,474
    Try...

    =SUM(IF(FREQUENCY(IF((A1:A9<>"")*(LEFT(B1:B9,6)="Level1")*(C1:C9="Acme"),MATCH(A1:A9,A1:A9,0)),ROW(INDEX(A1:A9,0,0))-ROW(A1)+1)>0,1,0))

    or

    =COUNT(1/FREQUENCY(IF((A1:A9<>"")*(LEFT(B1:B9,6)="Level1")*(C1:C9="Acme"),MATCH(A1:A9,A1:A9,0)),ROW(INDEX(A1:A9,0,0))-ROW(A1)+1))

    Both formulas need to be confirmed with CONTROL+SHIFT+ENTER, not just ENTER.

    Hope this helps!

    Quote Originally Posted by slc
    I have the similar situation except that Col A is not number but text. Tried both formulas (the ones without the LEFT function) but they returned 0 if Col A is text (not number). Can anyone help to advise how to amend the formula for this case. Thanks


    Column A: Column B: Column C: Column D:
    AP1 Level1a ACME 345334
    AP1 Level1b ACME 34523
    AP1 Level2 ACME 34622
    AP2 Level2 ACME 3453
    AP4 Level2 DODAD 345
    AP3 Level1a THINGABOB 322562
    AP5 Level1b WIDGET 34622
    AP2 Level2 WIDGET 3453
    AP6 Level3 WIDGET 546443

  9. #9
    Registered User
    Join Date
    10-09-2003
    Posts
    25
    Domenic,

    Thanks.

+ 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