+ Reply to Thread
Results 1 to 5 of 5

Headcount unique across 3 named ranges

  1. #1
    Forum Contributor
    Join Date
    08-16-2009
    Location
    Sheffield
    MS-Off Ver
    Excel 2010
    Posts
    109

    Headcount unique across 3 named ranges

    Hi,

    Any help appreciated to edit the formula in AI7 highlighted in yellow so that the 3 named ranges (bfast, Lunch, Evening) provides the total unique text.

    Basically this formula works well for 1 named range but I would like this to expand to all 3 areas as shown

    More detailed information on the sample file.

    Many thanks
    Garry
    Attached Files Attached Files

  2. #2
    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,830

    Re: Headcount unique across 3 named ranges

    Thinking outside the box(es) a little:

    =SUMPRODUCT((G6:AE8<>"")/COUNTIF(G6:AE8,G6:AE8&""))-IF(N7=W7,1,2)
    Last edited by AliGW; 07-29-2019 at 04:14 AM.
    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.

  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,053

    Re: Headcount unique across 3 named ranges

    One way, using this array formula:

    =SUM(IFERROR(1/(COUNTIF(bfast,bfast)+COUNTIF(Lunch,bfast)+COUNTIF(Evening,bfast)),0))
    +SUM(IFERROR(1/(COUNTIF(Lunch,Lunch)+COUNTIF(bfast,Lunch)+COUNTIF(Evening,Lunch)),0))
    +SUM(IFERROR(1/(COUNTIF(Evening,Evening)+COUNTIF(bfast,Evening)+COUNTIF(Lunch,Evening)),0))

    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.

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

  4. #4
    Forum Contributor
    Join Date
    08-16-2009
    Location
    Sheffield
    MS-Off Ver
    Excel 2010
    Posts
    109

    Re: Headcount unique across 3 named ranges

    Hi,

    Many thanks, and works well, great response and advice, love this forum.

    Regards
    Garry

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

    Re: Headcount unique across 3 named ranges

    Which did you choose, as a matter of interest?

+ 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] VBA creates named ranges, but named ranges disappear
    By BrotherNeptune in forum Excel Programming / VBA / Macros
    Replies: 2
    Last Post: 10-05-2015, 03:22 PM
  2. Replies: 6
    Last Post: 05-12-2014, 09:16 PM
  3. Define only 2 named ranges from a list of named ranges...
    By abhi900 in forum Excel Programming / VBA / Macros
    Replies: 6
    Last Post: 04-29-2014, 04:20 AM
  4. Looping Mutliple Named Resized Ranges in next empty row below another named range
    By gingumdog in forum Excel Programming / VBA / Macros
    Replies: 0
    Last Post: 03-19-2014, 08:15 PM
  5. Pulling Unique Data from named ranges
    By Cavinaar in forum Excel Formulas & Functions
    Replies: 0
    Last Post: 11-23-2013, 02:24 PM
  6. Replies: 1
    Last Post: 07-17-2013, 11:34 AM
  7. Excel 2007 : Headcount unique names
    By daniel_t in forum Excel General
    Replies: 2
    Last Post: 01-31-2011, 07:10 AM

Tags for this Thread

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