+ Reply to Thread
Results 1 to 5 of 5

Count unique entries based on two columns

Hybrid View

  1. #1
    Registered User
    Join Date
    10-06-2013
    Location
    England
    MS-Off Ver
    Excel 2003
    Posts
    2

    Count unique entries based on two columns

    Hi

    Hoping someone may be able to help with this one as it's driving me up the wall. I'm trying to count the number of unique occurrences of names in a list where a second condition is true

    Name | Attended
    ----------------
    Bob | Yes
    Jack | No
    Bob | Yes
    Dave | Yes
    Dave | No
    Stu | Yes
    Jack | No

    So, regardless of the number of occurrences of a unique name in column A they would only be counted once and only be counted if they had attended at least once (corresponding "Yes" in column B). The above would filter down as

    Bob
    Dave
    Stu

    Which would produce a count of 3

    I've tried using sumproduct but when adding in the condition of column B being "yes" it just doesn't add up correctly. Can anyone help?

  2. #2
    Forum Expert dredwolf's Avatar
    Join Date
    10-27-2012
    Location
    Clearwater,Canada
    MS-Off Ver
    Excel 2007
    Posts
    2,649

    Re: Count unique entries based on two columns

    Hrrm, difficult 1, I could not come up with a single cell solution (there may be one), so I used a helper column (C):
    C2:
    Formula: copy to clipboard
    =IF(COUNTIF($C$1:C1,IFERROR(SUMPRODUCT(MATCH(A2&"Yes",$A$2:$A$8&$B$2:$B$8,0)),"")),"",IFERROR(SUMPRODUCT(MATCH(A2&"Yes",$A$2:$A$8&$B$2:$B$8,0)),""))

    then this to get the Count:
    Formula: copy to clipboard
    =COUNT(C2:C8)

    which returns 3

    See attached

    Hope this helps
    Attached Files Attached Files
    A picture may be worth a thousand words, BUT, a sample Workbook is worth a thousand screenshots!
    -Add a File - click advanced (next to quick post), scroll to manage attachments, click, select add files, click select files, select file, click upload, when file shows up at bottom left, click done (bottom right), click submit
    -To mark thread Solved- go top of thread,click Thread Tools,click Mark as Solved
    If you received helpful response, please remember to hit the * of that post

  3. #3
    Forum Guru benishiryo's Avatar
    Join Date
    03-25-2011
    Location
    Singapore
    MS-Off Ver
    Excel 2013
    Posts
    5,156

    Re: Count unique entries based on two columns

    welcome to the forum, gradient. another alternative is with array formulas:
    =SUM(IF(FREQUENCY(IF(B2:B8="Yes",MATCH(A2:A8,A2:A8,0)),ROW(A2:A8)-ROW(A2)+1)>0,1))

    ...confirmed by pressing CTRL+SHIFT+ENTER to activate the array, not just ENTER. You will know the array is active when you see curly braces { } appear around your formula. If you do not CTRL+SHIFT+ENTER you will get an error or a clearly incorrect answer. Press F2 on that cell and try again.

    if you need the unique names say in E2 downwards, then this array formula would help:
    =LOOKUP("zzz",CHOOSE({1,2},"",INDEX($A$2:$A$10,MATCH(0,IF($B$2:$B$10="Yes",COUNTIF(E$1:E1,$A$2:$A$10)),0))))

    Thanks, if you have clicked on the * and added our rep.

    If you're satisfied with the answer, click Thread Tools above your first post, select "Mark your thread as Solved".

    "Contentment is not the fulfillment of what you want, but the realization of what you already have."


    Tips & Tutorials I Compiled | How to Get Quick & Good Answers

  4. #4
    Registered User
    Join Date
    10-06-2013
    Location
    England
    MS-Off Ver
    Excel 2003
    Posts
    2

    Re: Count unique entries based on two columns

    That's done the trick benishiryo

    =SUM(IF(FREQUENCY(IF(B2:B8="Yes", IF(A2:A8<>"", MATCH(A2:A8,A2:A8,0), 0)),ROW(A2:A8)-ROW(A2)+1)>0,1))

    I just had to slightly update the formula to check for blank cells and it works perfectly, thank you. Admittedly I don't quite understand how it's doing what it's doing so I'm going to have to sit down and work it through so I understand what you did, but I really appreciate the solution, I've been tearing my hair out trying to find any solution and particularily a one cell solution.

    @dredwolf

    Thanks for the solution. Up until I saw benishiryo's one cell solution this morning I had taken to implementing yours last night and it seemed to work which was a godsend, so thanks for the help too

  5. #5
    Forum Contributor arlu1201's Avatar
    Join Date
    09-09-2011
    Location
    Bangalore, India
    MS-Off Ver
    Excel 2003 & 2007
    Posts
    19,167

    Re: Count unique entries based on two columns

    Based on your last post in this thread, its apparent that you are satisfied with the solution(s) you've received and have solved your question, but you haven't marked your thread as "SOLVED". I will do it for you this time.

    In future, to mark your thread as Solved, you can do the following -
    Select Thread Tools-> Mark thread as Solved.

    Incase your issue is not solved, you can undo it as follows -
    Select Thread Tools-> Mark thread as Unsolved.

    Also, since you are relatively new to the forum, i would like to inform you that you can thank those who have helped you by clicking the small star icon located in the lower left corner of the post which helped you. This adds to the reputation of the person who has taken the time to help you.
    If I have helped, Don't forget to add to my reputation (click on the star below the post)
    Don't forget to mark threads as "Solved" (Thread Tools->Mark thread as Solved)
    Use code tags when posting your VBA code: [code] Your code here [/code]

+ Reply to Thread

Thread Information

Users Browsing this Thread

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

Similar Threads

  1. [SOLVED] Count unique entries across columns based on criteria
    By flomme in forum Excel Formulas & Functions
    Replies: 7
    Last Post: 08-15-2013, 06:43 PM
  2. Replies: 7
    Last Post: 07-27-2013, 10:11 PM
  3. [SOLVED] Count Unique Pairs of Excel Entries Based on Criteria
    By DonFord81 in forum Excel Formulas & Functions
    Replies: 1
    Last Post: 01-22-2013, 01:12 PM
  4. Replies: 14
    Last Post: 11-07-2012, 09:18 PM
  5. [SOLVED] count duplicate (or, inversely, unique) entries, but based on a condition
    By markx in forum Excel Formulas & Functions
    Replies: 3
    Last Post: 03-08-2005, 03:06 PM

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