+ Reply to Thread
Results 1 to 11 of 11

Formula to count unique value in a sheet based on multiple criteria

  1. #1
    Registered User
    Join Date
    08-01-2018
    Location
    Chennai
    MS-Off Ver
    2017
    Posts
    19

    Formula to count unique value in a sheet based on multiple criteria

    Hi,

    I have 2 sheets. Below is the scenario.

    In sheet1, I have a set of columns having the User IDs.
    In sheet2, I have the User Ids and number of account IDs. Acoount Ids can be duplicated for the user IDs

    In sheet1, I have to calculate the unique number of acoount Ids for each users.

    Please refer attached Excel sheet for sample data

    Please advise

    Thanks.
    Attached Files Attached Files

  2. #2
    Forum Moderator alansidman's Avatar
    Join Date
    02-02-2010
    Location
    Steamboat Springs, CO
    MS-Off Ver
    MS Office 365 Version 2404 Win 11 Home 64 Bit
    Posts
    23,865

    Re: Formula to count unique value in a sheet based on multiple criteria

    I am not sure exactly what you are looking for. Suggest you post the expected results so that we are clear on your needs as you did not explain clearly what you wanted for results.
    Alan עַם יִשְׂרָאֵל חַי


    Change an Ugly Report with Power Query
    Database Normalization
    Complete Guide to Power Query
    Man's Mind Stretched to New Dimensions Never Returns to Its Original Form

  3. #3
    Registered User
    Join Date
    06-25-2018
    Location
    Luna
    MS-Off Ver
    2013
    Posts
    46

    re: count DISTINCT



    the duplication in column B (account ID)
    is indeed troublesome---

  4. #4
    Forum Expert BadlySpelledBuoy's Avatar
    Join Date
    06-14-2013
    Location
    East Sussex, UK
    MS-Off Ver
    365
    Posts
    7,468

    Re: Formula to count unique value in a sheet based on multiple criteria

    I think the OP is looking for a unique count of Account IDs per User ID, so expected results(?) 47, 48, 6 and 36 in B2:B5 on Sheet1.

    Simple with a helper column (see attached), not quite so simple without it and without any real idea of how big the real data for this is then it's impossible to know whether the helper column or an array formula (the likely non helper solution) would really be suitable.

    BSB
    Attached Files Attached Files

  5. #5
    Forum Guru samba_ravi's Avatar
    Join Date
    07-26-2011
    Location
    Hyderabad, India
    MS-Off Ver
    Excel 2021
    Posts
    8,914

    Re: Formula to count unique value in a sheet based on multiple criteria

    b2=SUM((FREQUENCY(IF(Sheet2!$A$2:$A$154=$A2,MATCH(Sheet2!$B$2:$B$154,Sheet2!$B$2:$B$154,0)),ROW(Sheet2!$B$1:$B$154))>0)+0)
    try this array formula and copy towards down
    ...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.
    Samba

    Say thanks to those who have helped you by clicking Add Reputation star.

  6. #6
    Registered User
    Join Date
    08-01-2018
    Location
    Chennai
    MS-Off Ver
    2017
    Posts
    19

    Re: Formula to count unique value in a sheet based on multiple criteria

    Please see the attached sample with the expected outcome in sheet1.

    I need formula's in sheet1 column B.
    Attached Files Attached Files

  7. #7
    Forum Moderator alansidman's Avatar
    Join Date
    02-02-2010
    Location
    Steamboat Springs, CO
    MS-Off Ver
    MS Office 365 Version 2404 Win 11 Home 64 Bit
    Posts
    23,865

    Re: Formula to count unique value in a sheet based on multiple criteria

    I would use the Advanced filter function on the ribbon on the sort and filter tab and have the unique items posted to a helper column. Then using that helper column, employ the =countif function in Sheet1 Column B to find the number.
    Attached Files Attached Files

  8. #8
    Registered User
    Join Date
    08-01-2018
    Location
    Chennai
    MS-Off Ver
    2017
    Posts
    19

    Re: Formula to count unique value in a sheet based on multiple criteria

    Thanks

    But I cant have the duplicates removed and then counted.
    This is a real time file and the formula should be dynamic.

  9. #9
    Forum Expert BadlySpelledBuoy's Avatar
    Join Date
    06-14-2013
    Location
    East Sussex, UK
    MS-Off Ver
    365
    Posts
    7,468

    Re: Formula to count unique value in a sheet based on multiple criteria

    Perhaps using Samba's array formula from post #5 but replacing the range references with dynamic named ranges would work?

    In the formula below I've done that with two named ranges called 'AccountOwner' and 'AccountID'.
    Formula: copy to clipboard
    Please Login or Register  to view this content.


    The named ranges are created using a formula such as the one below:
    Formula: copy to clipboard
    Please Login or Register  to view this content.


    Open the attached and press Ctrl+F3 to open the Named Range Manager to see them both.

    BSB
    Attached Files Attached Files

  10. #10
    Forum Expert BadlySpelledBuoy's Avatar
    Join Date
    06-14-2013
    Location
    East Sussex, UK
    MS-Off Ver
    365
    Posts
    7,468

    Re: Formula to count unique value in a sheet based on multiple criteria

    If you need the list on Sheet1 to be dynamic too then you'll be needing a formula for that.
    Plenty of example on how to that. Just search for "Unique list from range".

    BSB

  11. #11
    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,491

    Re: Formula to count unique value in a sheet based on multiple criteria

    Rule 08: Cross-posting Without Telling Us

    Your post does not comply with Rule 8 of our Forum RULES. Do not cross-post your question on multiple forums without telling us about your threads on other forums.

    Post a link to any other forums where you have asked the same question. If you have fewer than 10 posts here, you will not be able to post a link, but you must still tell us where else you have asked the question.

    Cross-posting is when you post the same question in other forums on the web. The last thing you want to do is waste people's time working on an issue you have already resolved elsewhere. We prefer that you not cross-post at all, but if you do (and it's unlikely to go unnoticed), you MUST provide a link (copy the url from the address bar in your browser) to the cross-post.

    Expect cross-posted questions without a link to be closed and a message will be posted by the moderator explaining why. We are here to help so help us to help you!

    Read this to understand why we ask you to do this, and then please edit your first post to include links to any and all cross-posts in any other forums (not just this site).

    If you have less than 10 posts, do not try to copy and paste the link. Instead, type the link out in your thread.

    No further help to be offered, please, until the OP has complied with this request.
    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.

+ 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. Count unique names based on multiple criteria
    By Ableandy in forum Excel Formulas & Functions
    Replies: 4
    Last Post: 03-11-2018, 06:34 AM
  2. [SOLVED] Need to count unique items based on multiple criteria
    By NS4Excel in forum Excel Formulas & Functions
    Replies: 22
    Last Post: 02-28-2017, 02:24 AM
  3. Count unique values based on multiple criteria
    By Jonathan11235 in forum Excel Formulas & Functions
    Replies: 13
    Last Post: 05-19-2015, 10:02 PM
  4. Replies: 6
    Last Post: 04-20-2015, 07:22 AM
  5. [SOLVED] Unique value count based on multiple criteria
    By Ronny66 in forum Excel Formulas & Functions
    Replies: 3
    Last Post: 08-06-2013, 10:18 AM
  6. Formula to count Unique text based on multiple criteria
    By OAMPS in forum Excel Formulas & Functions
    Replies: 4
    Last Post: 06-14-2012, 10:48 AM
  7. [SOLVED] how to count unique values in excel based on multiple criteria
    By IDBUGM in forum Excel Formulas & Functions
    Replies: 3
    Last Post: 03-15-2006, 12:10 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