+ Reply to Thread
Results 1 to 6 of 6

Count cells only once

  1. #1
    Registered User
    Join Date
    11-06-2013
    Location
    Hamburg
    MS-Off Ver
    Excel 2010
    Posts
    1

    Lightbulb Count cells only once

    Dear all,

    I found this function to count cells only once...

    =SUMPRODUCT(($A$10:$A$10000<>"")/COUNTIF($A$10:$A$10000,$A$10:$A$10000&""))

    It works perfectly but I canīt understand how. the countif gives 0. How can something divided for 0 work?

    Thank you for your clarification.

    Filippo

  2. #2
    Forum Guru TMS's Avatar
    Join Date
    07-15-2010
    Location
    The Great City of Manchester, NW England ;-)
    MS-Off Ver
    MSO 2007,2010,365
    Posts
    44,084

    Re: Count cells only once

    Try it on a smaller sample and use Formulas | Formula Auditing | Evaluate Formula to see what it is doing.

    Formula: copy to clipboard
    Please Login or Register  to view this content.


    It actually generates a matrix of TRUEs and FALSEs that become 0s and 1s ... which the SUMPRODUCT adds up.

    You can split it up:

    Formula: copy to clipboard
    Please Login or Register  to view this content.


    and:

    Formula: copy to clipboard
    Please Login or Register  to view this content.



    However, the second formula, as a standalone entity would need to be Array Entered using Ctrl-Shift-Enter rather than just Enter.

    So you would see:

    Formula: copy to clipboard
    Please Login or Register  to view this content.



    Regards, TMS
    Trevor Shuttleworth - Retired Excel/VBA Consultant

    I dream of a better world where chickens can cross the road without having their motives questioned

    'Being unapologetic means never having to say you're sorry' John Cooper Clarke


  3. #3
    Forum Guru :) Sixthsense :)'s Avatar
    Join Date
    01-01-2012
    Location
    India>Tamilnadu>Chennai
    MS-Off Ver
    2003 To 2010
    Posts
    12,767

    Re: Count cells only once

    Make use of Evaluate Button Under the Formulas Tab>>Formula Auditing

    Refer the formula to few cells like 3 or five cells and use evaluate to know how it works


    If your problem is solved, then please mark the thread as SOLVED>>Above your first post>>Thread Tools>>
    Mark your thread as Solved


    If the suggestion helps you, then Click *below to Add Reputation

  4. #4
    Forum Guru TMS's Avatar
    Join Date
    07-15-2010
    Location
    The Great City of Manchester, NW England ;-)
    MS-Off Ver
    MSO 2007,2010,365
    Posts
    44,084

    Re: Count cells only once

    Sorry, maybe an example.

    Say A10 to A16 have 10, 11, 12, 13, 10, space, 16, in them.

    Formula: copy to clipboard
    Please Login or Register  to view this content.
    =5


    Formula: copy to clipboard
    Please Login or Register  to view this content.
    =6


    Formula: copy to clipboard
    Please Login or Register  to view this content.
    =2


    However, the matrix that SUMPRODUCT adds up will be 0.5, 1, 1, 1, 0.5, 0, 1, 0, 0, 0.

    That's because there are two 10's, hence the two 0.5s, and one each of 11, 12, 13 and 16.


    Regards, TMS

  5. #5
    Forum Guru TMS's Avatar
    Join Date
    07-15-2010
    Location
    The Great City of Manchester, NW England ;-)
    MS-Off Ver
    MSO 2007,2010,365
    Posts
    44,084

    Re: Count cells only once

    Thanks for the rep

  6. #6
    Forum Expert Tony Valko's Avatar
    Join Date
    12-31-2011
    Location
    Pittsburgh
    MS-Off Ver
    2002, 2007:2013
    Posts
    18,890

    Re: Count cells only once

    This demonstrates the individual steps of the formula.


    Data Range
    A
    B
    C
    D
    E
    2
    A
    TRUE
    2
    0.5
    5
    3
    A
    TRUE
    2
    0.5
    4
    FALSE
    1
    0
    5
    B
    TRUE
    1
    1
    6
    C
    TRUE
    2
    0.5
    7
    C
    TRUE
    2
    0.5
    8
    D
    TRUE
    1
    1
    9
    E
    TRUE
    2
    0.5
    10
    E
    TRUE
    2
    0.5


    Enter this formula in B2 and copy down to B10:

    =A2<>""

    Enter this formula in C2 and copy down to C10:

    =COUNTIF(A$2:A$10,A2&"")

    Enter this formula in D2 and copy down to D10:

    =B2/C2

    Enter this formula in E2:

    =SUM(D2:D10)

    So:

    =SUMPRODUCT((A2:A10<>"")/COUNTIF(A2:A10,A2:A10&""))

    =5 unique entries (excluding empty cells)

    Now, try this....

    To see why we do this:

    COUNTIF(A2:A10,A2:A10&"")

    Change the formula in C2 to:

    =COUNTIF(A$2:A$10,A2)

    And copy down to C10.

    Note the result in cell E2.

    If there won't be any empty cells in the data range then you can use this shorter version:

    =SUMPRODUCT(1/COUNTIF(A2:A10,A2:A10))
    Biff
    Microsoft MVP Excel
    Keep It Simple Stupid

    Let's Go Pens. We Want The Cup.

+ 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] Formula needed to only count total cells entered and not count adjacent text entered cells
    By excelteam777 in forum Excel Formulas & Functions
    Replies: 4
    Last Post: 07-07-2013, 06:22 PM
  2. [SOLVED] count cells that contain text but do not count cells containing only a formula
    By cprpacific in forum Excel Formulas & Functions
    Replies: 6
    Last Post: 03-13-2013, 03:15 PM
  3. [SOLVED] Count in a range, where identical adjacent cells count as one instance.
    By the-algebraist in forum Excel Formulas & Functions
    Replies: 6
    Last Post: 02-05-2013, 11:18 AM
  4. [SOLVED] count occupied cells, but put count total in different worksheet
    By NewbieOfVBA in forum Excel Programming / VBA / Macros
    Replies: 6
    Last Post: 07-24-2012, 07:30 PM
  5. Replies: 2
    Last Post: 06-24-2010, 04:53 PM

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