+ Reply to Thread
Results 1 to 7 of 7

Count unique values based on date

  1. #1
    Registered User
    Join Date
    03-01-2019
    Location
    Berlin
    MS-Off Ver
    Office 365
    Posts
    3

    Count unique values based on date

    Hello Excel experts,

    I have the following table:

    (A) Date ||| (B) ID
    (1) 20/10/2019 ||| 12345
    (2) 20/10/2019 ||| 54321
    (3) 20/10/2019 ||| 43251
    (4) 20/10/2019 ||| 12345
    (5) 19/10/2019 ||| 11111
    (6) 19/10/2019 ||| 22222
    (7) 19/10/2019 ||| 33333
    (8) 19/10/2019 ||| 44444

    And I would like to count the unique IDs per date on that table, getting as result something like this:

    Date ||| Unique count of IDs
    20/10/2019 |||| 3
    19/10/2019 |||| 4


    Any help? Can't make it work by myself using google's help.
    Last edited by Charly123; 10-21-2019 at 03:42 AM.

  2. #2
    Forum Expert PaulM100's Avatar
    Join Date
    10-09-2017
    Location
    UK
    MS-Off Ver
    Office 365
    Posts
    2,108

    Re: Count unique values based on date

    Try: =SUM(--(FREQUENCY(IF($A$2:$A$10=$E5,$B$2:$B$10),$B$2:$B$10)>0)) as an array formula confirmed with Ctrl+Shift+Enter
    Click the * to say thanks.

  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
    44,118

    Re: Count unique values based on date

    If that's not it...

    Will you please attach a SMALL sample Excel workbook (10-20 rows of data is usually enough)? However, please give us an indication of the approximate number of rows of data you want the solution to work with (100, 1000, 100,000 or whatever). Please DO NOT attach a picture of an Excel sheet (I do not have the patience to re-type any/all your stuff before starting).

    1. It does NOT have to be your real sheet - mock up a SAMPLE if you need to. But not 1000's of rows!!! It makes manual checking so tedious. Whatever you do... make sure that all confidential information is removed first!!

    2. Make sure that your sample data are truly REPRESENTATIVE of your real data. For example, don't show text in a column if it's really a number. The use of unrepresentative data is very frustrating and can lead to long delays in reaching a solution.

    3. Make sure that your desired solution is also shown (mock up the results manually). To be honest, I am not interested in seeing a non-working formula... or a pile of blank cells. However, I am very interested in seeing your EXPECTED results in their EXPECTED location.

    4. Try not to use merged cells. They cause lots of problems and are DEFINITELY best avoided!

    Unfortunately the attachment icon doesn't work at the moment. So, to attach an Excel file you have to do the following: Just before posting, scroll down to Go Advanced and then scroll down to Manage Attachments. Now follow the instructions at the top of that screen.
    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

  4. #4
    Registered User
    Join Date
    03-01-2019
    Location
    Berlin
    MS-Off Ver
    Office 365
    Posts
    3

    Re: Count unique values based on date

    This worked, thank you very much.
    Try: =SUM(--(FREQUENCY(IF($A$2:$A$10=$E5,$B$2:$B$10),$B$2:$B$10)>0)) as an array formula confirmed with Ctrl+Shift+Enter
    However, I have around 500.000 rows to play with and the array formulas are consuming too much resources. Is there another way you would recommend?
    Last edited by Charly123; 10-21-2019 at 08:12 AM.

  5. #5
    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
    44,118

    Re: Count unique values based on date

    Possibly. Post a sample sheet. I don't want to have to figure out what your sheet looks like and then reproduce it myself.

  6. #6
    Registered User
    Join Date
    03-01-2019
    Location
    Berlin
    MS-Off Ver
    Office 365
    Posts
    3

    Re: Count unique values based on date

    Apologies, attached you have a sample sheet.
    Attached Files Attached Files

  7. #7
    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
    44,118

    Re: Count unique values based on date

    Here's an alternative. No idea if it's any better!!

    =SUM(INDEX(($B$5:$B$15=E8)/COUNTIFS($B$5:$B$15,$B$5:$B$15&"",$C$5:$C$15,$C$5:$C$15&""),0))

    Just use Enter....
    Attached Files Attached Files

+ 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 values based on value with date range
    By papasmurfuo9 in forum Excel Formulas & Functions
    Replies: 6
    Last Post: 05-24-2018, 07:24 AM
  2. Count of Unique Values Based on Date in Another Column
    By masood78 in forum Excel Formulas & Functions
    Replies: 7
    Last Post: 12-13-2015, 03:46 AM
  3. [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
  4. [SOLVED] Count Unique Values Based on Earliest Date Criteria
    By Aquamore in forum Excel Formulas & Functions
    Replies: 3
    Last Post: 10-04-2014, 09:12 PM
  5. [SOLVED] count unique values across multiple sheets based on date
    By roninn75 in forum Excel General
    Replies: 8
    Last Post: 02-25-2014, 05:20 PM
  6. [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
  7. count unique values in columns based on date values
    By cclntn in forum Excel Programming / VBA / Macros
    Replies: 4
    Last Post: 07-29-2010, 06:16 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