+ Reply to Thread
Results 1 to 14 of 14

In different Filters distinct values give a count in the last row.

  1. #1
    Registered User
    Join Date
    08-12-2015
    Location
    india
    MS-Off Ver
    2010
    Posts
    44

    In different Filters distinct values give a count in the last row.

    Dear Excel hero's

    In want the count of the distinct values of the column based on my filter in the last row.

    Based on my filter it should dynamically provide me the values.

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

    Re: In different Filters distinct values give a count in the last row.

    There may be a few heros here... but there are no mind readers.

    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 don't attach a picture of an Excel sheet (no-one will want to re-type 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. 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).

    4. Try to avoid using merged cells. They cause lots of problems!

    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

  3. #3
    Registered User
    Join Date
    08-12-2015
    Location
    india
    MS-Off Ver
    2010
    Posts
    44

    Re: In different Filters distinct values give a count in the last row.

    Attachment uploaded with the expected result. and example
    Attached Files Attached Files

  4. #4
    Forum Expert
    Join Date
    07-20-2011
    Location
    Mysore, India.
    MS-Off Ver
    Excel 2019
    Posts
    8,710

    Re: In different Filters distinct values give a count in the last row.

    ARRAY formula in C14
    Please Login or Register  to view this content.
    Attached Files Attached Files
    Pl note
    Array formula should be confirmed with Ctrl+Shift+Enter keys together.
    If answere is satisfactory press * to add reputation.

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

    Re: In different Filters distinct values give a count in the last row.

    This array formula:

    =SUM(IF(FREQUENCY(IF(SUBTOTAL(3,OFFSET($C$2,ROW($C$2:$C$14)-ROW($C$2),)),IF($C$2:$C$14<>"",MATCH($C$2:$C$14,$C$2:$C$14,0))),ROW($C$2:$C$14)-ROW($C$2)+1),1))

    gives you the expected results.

    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

  6. #6
    Registered User
    Join Date
    08-12-2015
    Location
    india
    MS-Off Ver
    2010
    Posts
    44

    Re: In different Filters distinct values give a count in the last row.

    Seems it is working, but when i filter less than are equal to 2000 in the example sheet, it shoul dgive answer 2, but it gives 1 which wrong.

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

    Re: In different Filters distinct values give a count in the last row.

    Who are you talking to??????

  8. #8
    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,662

    Re: In different Filters distinct values give a count in the last row.

    I can see that mine gives 1... Why are you expecting 2 as the answer when both values <=2000 are from order number 1?????

  9. #9
    Registered User
    Join Date
    08-12-2015
    Location
    india
    MS-Off Ver
    2010
    Posts
    44

    Re: In different Filters distinct values give a count in the last row.

    Hi Glenn Kennedy

    Seems it is working, but when i filter less than are equal to 2000 in the example sheet, it should give answer 2, but it gives 1 which wrong

    =SUM(IF(FREQUENCY(IF(SUBTOTAL(3,OFFSET($C$2,ROW($C$2:$C$14)-ROW($C$2),)),IF($C$2:$C$14<>"",MATCH($C$2:$C$14,$C$2:$C$14,0))),ROW($C$2:$C$14)-ROW($C$2)+1),1))

    .

  10. #10
    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,662

    Re: In different Filters distinct values give a count in the last row.

    So.. Please answer my Q at post 8

  11. #11
    Registered User
    Join Date
    08-12-2015
    Location
    india
    MS-Off Ver
    2010
    Posts
    44

    Re: In different Filters distinct values give a count in the last row.

    Glenn Perfect, this solves my issue. thanks a lot.

  12. #12
    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,662

    Re: In different Filters distinct values give a count in the last row.

    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.

  13. #13
    Registered User
    Join Date
    08-12-2015
    Location
    india
    MS-Off Ver
    2010
    Posts
    44

    Re: In different Filters distinct values give a count in the last row.

    Glenn usually we do delete duplicates to get the distinct value. now you above formula sort the problem and it will automatically provide the answer.

    Is there any other easy way to achieve. i just what the distinct values

  14. #14
    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,662

    Re: In different Filters distinct values give a count in the last row.

    I moved your table down a bit to make seeing the results easier...

    =SUMPRODUCT(SUBTOTAL(103,OFFSET($C$5,ROW($C$5:$C$17)-ROW($C$5),0)))
    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. How can I count the distinct values
    By rizz0 in forum Excel Formulas & Functions
    Replies: 4
    Last Post: 04-13-2017, 09:33 AM
  2. Count of Values (Rows) of Most Recent Consecutive Streak (2+ Distinct Values)
    By ExcelForum88 in forum Excel Formulas & Functions
    Replies: 2
    Last Post: 03-13-2016, 12:26 PM
  3. count distinct values in excel
    By annux08 in forum Excel General
    Replies: 3
    Last Post: 07-13-2015, 09:21 AM
  4. Count Distinct Values
    By trevordsmith in forum Excel Formulas & Functions
    Replies: 4
    Last Post: 07-02-2014, 09:21 PM
  5. [SOLVED] Count Distinct Values OFFSET
    By GregM56 in forum Excel Formulas & Functions
    Replies: 6
    Last Post: 08-22-2013, 10:13 AM
  6. [SOLVED] Count Distinct Values
    By djfatboyfats in forum Excel Formulas & Functions
    Replies: 7
    Last Post: 11-20-2012, 07:39 AM
  7. Count Distinct Values?
    By bill_morgan in forum Excel Formulas & Functions
    Replies: 8
    Last Post: 04-26-2005, 10:06 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