+ Reply to Thread
Results 1 to 5 of 5

Counting Unique Values for Multiple Criteria

Hybrid View

  1. #1
    Registered User
    Join Date
    02-21-2018
    Location
    Canada
    MS-Off Ver
    2010
    Posts
    2

    Counting Unique Values for Multiple Criteria

    Hi all,

    I am currently making an inventory and am trying to get some stats going on the data but don't know how to count the exceptions.

    I'm trying to count the # of people who are assigned to a cabinet. We have broken it down by cabinet (numbered) and drawers (lettered). The problem I'm running into is if one cabinet has multiple owners. I don't want to count of the cabinet to be off but I would like to show a summary of how many cabinets each person owns. I've put everything into a Pivot Table and have a hidden column that only has the Cabinet #s once and the PivotTable uses those to count the # of cabinets per person. However, the problem I'm having is that if drawer B or C is owned by another person, those aren't being accounted for when breaking down by owner. Basically, I don't want a breakdown of the # of drawers each person owns, I just want a summary showing the # of cabinets they are shown under. If one person owns all the drawers in the cabinet, it should show as 1. However, if there are two names, each name should have 1.

    Any help would be appreciated!
    Capture.PNG

  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 2406
    Posts
    44,562

    Re: Counting Unique Values for Multiple Criteria

    Did you get the expected answer for Mark wrong??

    =SUM(IF(FREQUENCY(IF(($D$2:$D$13=F2)*($B$2:$B$13<>""),$B$2:$B$13),$B$2:$B$13),1))

    This is an array formula and will also work if there are blank cells in the range.

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

  3. #3
    Banned User!
    Join Date
    02-05-2015
    Location
    San Escobar
    MS-Off Ver
    any on PC except 365
    Posts
    12,168

    Cool Re: Counting Unique Values for Multiple Criteria

    or install PowerPivot and use it with data without blank cells in #

    datamodel.jpg

    check add to data model
    Last edited by sandy666; 02-21-2018 at 02:20 PM.

  4. #4
    Registered User
    Join Date
    02-21-2018
    Location
    Canada
    MS-Off Ver
    2010
    Posts
    2

    Re: Counting Unique Values for Multiple Criteria

    Thank you all!!! Really appreciate the quick help!

  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 2406
    Posts
    44,562

    Re: Counting Unique Values for Multiple Criteria

    You're welcome.



    If that takes care of your original question, please select "Thread Tools" from the menu link above and mark this thread as SOLVED.

    It'd also be appreciated if you were to click the Add Reputation button at the foot of any of the posts of all members who helped you reach a solution.

+ 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. Counting Unique values with multiple criteria
    By qussai in forum Excel Formulas & Functions
    Replies: 5
    Last Post: 06-10-2017, 07:10 AM
  2. counting unique values with multiple criteria
    By freil in forum Excel Formulas & Functions
    Replies: 19
    Last Post: 12-12-2016, 06:19 PM
  3. [SOLVED] Counting unique values with multiple criteria
    By f.bomb in forum Excel General
    Replies: 5
    Last Post: 08-13-2014, 05:00 AM
  4. [SOLVED] Counting Unique/Different Values based on multiple Criteria
    By jdodz in forum Excel Formulas & Functions
    Replies: 2
    Last Post: 01-22-2014, 05:41 PM
  5. Counting Unique Values on Multiple Criteria
    By buhwheet in forum Excel Formulas & Functions
    Replies: 8
    Last Post: 01-10-2014, 01:32 AM
  6. [SOLVED] Counting Unique Values with Multiple Criteria
    By smwbuddy in forum Excel Formulas & Functions
    Replies: 4
    Last Post: 04-15-2013, 08:35 PM
  7. Counting Unique Values with Multiple Criteria
    By CELIA.NEFF in forum Excel General
    Replies: 10
    Last Post: 02-15-2012, 11:31 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