+ Reply to Thread
Results 1 to 7 of 7

Count unique values based on another cell value

  1. #1
    Registered User
    Join Date
    08-16-2016
    Location
    London, England
    MS-Off Ver
    2013
    Posts
    88

    Count unique values based on another cell value

    Hi,

    I have a sheet where I'm wanting to count unique values in column A where Column B is not blank or is greater than zero. Please see the attached sample file will hopefully make it easier to understand.

    I realise I could achieve this with a pivot table, but ideally I'd like a formula as it would makes things a lot easier for me with other tasks I have on the real sheet.

    Any help or advice would be great!
    Attached Files Attached Files

  2. #2
    Forum Moderator Glenn Kennedy's Avatar
    Join Date
    07-08-2012
    Location
    Digital Nomad... occasionally based in Ireland.
    MS-Off Ver
    O365 (PC) V 2403
    Posts
    43,984

    Re: Count unique values based on another cell value

    One way, with an array formula:

    =SUM(IF($B$2:$B$33>0,1/COUNTIFS($A$2:$A$33,$A$2:$A$33,$B$2:$B$33,">0")))
    Attached Files Attached Files
    Glenn




    None of us get paid for helping you... we do this for fun. So DON'T FORGET to say "Thank You" to all who have freely given some of their time to help YOU.

    Temporary addition of accented to illustrate ongoing problem to the TT: L? fh?ile P?draig sona dhaoibh

  3. #3
    Forum Moderator Glenn Kennedy's Avatar
    Join Date
    07-08-2012
    Location
    Digital Nomad... occasionally based in Ireland.
    MS-Off Ver
    O365 (PC) V 2403
    Posts
    43,984

    Re: Count unique values based on another cell value

    Oops.

    Array Formulae are a little different from ordinary formulae in that they MUST be confirmed in the FIRST CELL ONLY by pressing CTRL+SHIFT+ENTER to activate the array, not just ENTER. After that, the array can be dragged down as normal, to cover the desired range.

    You will know the array is active when you see curly brackets { } - or "curly braces" for those of you in the USA, or "flower brackets" for those of you in India - appear around the outside of your formula. If you do not use CTRL+SHIFT+ENTER you will (almost always) get an error message or an incorrect answer. Press F2 on that cell and try again.

    Don't type the curly brackets yourself - it won't work...

  4. #4
    Forum Moderator AliGW's Avatar
    Join Date
    08-10-2013
    Location
    Retired in Ipswich, Suffolk, but grew up in Sawley, Derbyshire (England)
    MS-Off Ver
    MS 365 Subscription Insider Beta Channel v. 2404 (Windows 11 22H2 64-bit)
    Posts
    80,410

    Re: Count unique values based on another cell value

    Another way:

    =SUM(--(FREQUENCY(IF($B$1:$B$16>0,MATCH($A$1:$A$16,$A$1:$A$16,0)),ROW($B$1:$B$16)-ROW(B1)+1)>0))

    ... 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.
    Ali


    Enthusiastic self-taught user of MS Excel who's always learning!
    Don't forget to say "thank you" in your thread to anyone who has offered you help.
    You can reward them by clicking on * Add Reputation below their user name on the left, if you wish.

    Forum Rules (updated August 2023): please read them here.

  5. #5
    Registered User
    Join Date
    08-16-2016
    Location
    London, England
    MS-Off Ver
    2013
    Posts
    88

    Re: Count unique values based on another cell value

    Sorted, thanks guys!

  6. #6
    Forum Moderator Glenn Kennedy's Avatar
    Join Date
    07-08-2012
    Location
    Digital Nomad... occasionally based in Ireland.
    MS-Off Ver
    O365 (PC) V 2403
    Posts
    43,984

    Re: Count unique values based on another cell value

    You're welcome and thanks for the rep.

  7. #7
    Forum Moderator AliGW's Avatar
    Join Date
    08-10-2013
    Location
    Retired in Ipswich, Suffolk, but grew up in Sawley, Derbyshire (England)
    MS-Off Ver
    MS 365 Subscription Insider Beta Channel v. 2404 (Windows 11 22H2 64-bit)
    Posts
    80,410

    Re: Count unique values based on another cell value

    Glad to have helped and ditto.

+ 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] Find count of Unique or Duplicate Values based on Concatenated values in 2 columns
    By bdicarlo1 in forum Excel Formulas & Functions
    Replies: 9
    Last Post: 12-03-2014, 12:42 AM
  2. Count Unique values in Column based on values in other columns
    By dmschave in forum Excel Formulas & Functions
    Replies: 2
    Last Post: 03-17-2014, 11:06 AM
  3. Count unique values based on value in another cell in same row
    By danbak in forum Excel Formulas & Functions
    Replies: 4
    Last Post: 08-08-2013, 03:54 AM
  4. [SOLVED] count unique values based on unique values
    By neetu.aggarwal in forum Excel General
    Replies: 13
    Last Post: 10-23-2012, 04:00 AM
  5. Count unique values and create list based on these values
    By Alan Beban in forum Excel Formulas & Functions
    Replies: 14
    Last Post: 09-06-2005, 07:05 AM
  6. Count unique values and create list based on these values
    By Alan Beban in forum Excel Formulas & Functions
    Replies: 21
    Last Post: 09-06-2005, 04:05 AM
  7. Count unique values and create list based on these values
    By vipa2000 in forum Excel Formulas & Functions
    Replies: 0
    Last Post: 09-06-2005, 03:05 AM
  8. Count unique values and create list based on these values
    By vipa2000 in forum Excel Formulas & Functions
    Replies: 0
    Last Post: 09-06-2005, 01:05 AM

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