+ Reply to Thread
Results 1 to 3 of 3

How to count unique entries that meet two criteria

Hybrid View

  1. #1
    Forum Contributor
    Join Date
    09-17-2009
    Location
    Torquay, England
    MS-Off Ver
    Excel 2013
    Posts
    253

    How to count unique entries that meet two criteria

    Hi I am trying to count all records that fall between the ages of 14 - 18.

    The ID numbers relating to each record may appear more than once on a long list so I need to count each ID only once.

    Example attached.

    EG an ID (relating to a person) may appear 3 times in a list of 200. I want to count them if they are between age 14 and 18 but I only want to count them once, not three times.

    Thanks - example attached
    Attached Files Attached Files

  2. #2
    Valued Forum Contributor ron2k_1's Avatar
    Join Date
    09-30-2009
    Location
    Not the USA
    MS-Off Ver
    Excel 2003, 2007
    Posts
    606

    Re: How to count unique entries that meet two criteria

    Not quite sure if what your objective is and where you want it, but what about modifying your formula on E6 and dragged down works:
    =IF(AND(C6>=$G$1,C6<=$G$2,COUNTIF($A$6:$A6,A6)=1),1,0)
    Ron
    Knowledge is knowing that a tomato and pepper are fruits. Wisdom is knowing whether to put these in a fruit salad

    Kindly

    [1] Use code tags. Place "[code]" before the first line of code and "[/code"]" after the last line of code. Exclude quotation marks
    [2] Mark your post [SOLVED] if it has been answered satisfactorily by editing your original post in advanced mode.
    [3] Thank (using the little scale) those that provided useful help; its nice and its very well appreciated

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

    Re: How to count unique entries that meet two criteria

    Single array formula alternative:

    =COUNT(1/FREQUENCY(IF(C$6:C$96>=$G$1,IF(C$6:C$96<=$G$2,IF($A$6:$A$96<>"",MATCH($A$6:$A$96,$A$6:$A$96,0)))),ROW($A$6:$A$96)-ROW($A$6)+1))
    and

    =COUNT(1/FREQUENCY(IF(D$6:D$96>=$G$1,IF(D$6:D$96<=$G$2,IF($A$6:$A$96<>"",MATCH($A$6:$A$96,$A$6:$A$96,0)))),ROW($A$6:$A$96)-ROW($A$6)+1))
    both confirmed with CTRL+SHIFT+ENTER not just ENTER
    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.

+ 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