+ Reply to Thread
Results 1 to 14 of 14

Excel 2007 : Constructing a formula that counts distinct words in a single cell

  1. #1
    Registered User
    Join Date
    01-20-2010
    Location
    United States
    MS-Off Ver
    Excel 2007
    Posts
    8

    Constructing a formula that counts distinct words in a single cell

    Here is what I need. I need to be able to count text in a single cell without the duplicates being counted. For example a single cell may contain the following:

    1, 2, 3, 4, 4, 5, 5

    I already have the formula that will count all of the characters an trim the spaces and give me a result of 7.

    I need a formula that will do the same thing, but not count the duplicates, giving me a result of 5.

    Any help would be greatly appreciated! Thanks in advance!

    April
    Last edited by NBVC; 01-20-2010 at 11:49 PM.

  2. #2
    Forum Expert NBVC's Avatar
    Join Date
    12-06-2006
    Location
    Mississauga, CANADA
    MS-Off Ver
    2003:2010
    Posts
    34,898

    Re: Need help with a formula

    Welcome to the forum,

    Your post does not comply with Rule 1 of our Forum RULES. Your post title should accurately and concisely describe your problem, not your anticipated solution. Use terms appropriate to a Google search. Poor thread titles, like Please Help, Urgent, Need Help, Formula Problem, Code Problem, and Need Advice will be addressed according to the OP's experience in the forum: If you have less than 10 posts, expect (and respond to) a request to change your thread title. If you have 10 or more posts, expect your post to be locked, so you can start a new thread with an appropriate title.
    To change a Title on your post, click EDIT then Go Advanced and change your title, if 2 days have passed ask a moderator to do it for you.
    Where there is a will there are many ways.

    If you are happy with the results, please add to the contributor's reputation by clicking the reputation icon (star icon) below left corner

    Please also mark the thread as Solved once it is solved. Check the FAQ's to see how.

  3. #3
    Forum Expert NBVC's Avatar
    Join Date
    12-06-2006
    Location
    Mississauga, CANADA
    MS-Off Ver
    2003:2010
    Posts
    34,898

    Re: Constructing a formula that counts distinct words in a single cell

    Try

    =SUM(IF(LEN(A1)-LEN(SUBSTITUTE(A1,{1,2,3,4,5,6,7,8,9},"")),1))

    confirmed with CTRL+SHIFT+ENTER not just ENTER...

    change A1 to actual cell reference first.

  4. #4
    Forum Expert daddylonglegs's Avatar
    Join Date
    01-14-2006
    Location
    England
    MS-Off Ver
    2016
    Posts
    14,675

    Re: Constructing a formula that counts distinct words in a single cell

    If you only have single digits as per your example then this formula will count them

    =COUNT(FIND({1,2,3,4,5,6,7,8,9,0},A1))

    but

  5. #5
    Forum Expert NBVC's Avatar
    Join Date
    12-06-2006
    Location
    Mississauga, CANADA
    MS-Off Ver
    2003:2010
    Posts
    34,898

    Re: Constructing a formula that counts distinct words in a single cell

    If you only have single digits as per your example then this formula will count them

    =COUNT(FIND({1,2,3,4,5,6,7,8,9,0},A1))
    Indeed, a better alternative

    I guess if you have 2 or 3 digit numbers too.. then you can use:

    =COUNT(FIND(ROW(INDIRECT({"1:1000"}))-1,A1))

    confimed with CTRL+SHIFT+ENTER...

    Change 1000 if larger than 3-digit numbers can be found
    Last edited by NBVC; 01-20-2010 at 04:03 PM.

  6. #6
    Registered User
    Join Date
    01-20-2010
    Location
    United States
    MS-Off Ver
    Excel 2007
    Posts
    8

    Re: Constructing a formula that counts distinct words in a single cell

    Thank you for responding. I tried that formula, but the result returned a "0".

    Ok, this is the formula I used in order to count all the numbers (words) in the single cell, eliminating spaces. Is there a way to manipulate this formula so that it does the exact same thing, except counting the duplicates only once? The numbers will only be 1-32.

    =IF(LEN(TRIM(Jan!G2))=0,0,LEN(TRIM(Jan!G2))-LEN(SUBSTITUTE(Jan!G2," ",""))+1)

  7. #7
    Forum Expert NBVC's Avatar
    Join Date
    12-06-2006
    Location
    Mississauga, CANADA
    MS-Off Ver
    2003:2010
    Posts
    34,898

    Re: Constructing a formula that counts distinct words in a single cell

    Try:

    =COUNT(FIND(ROW(INDIRECT({"1:32"})),Jan!G2))

    Hold the CTRL and SHIFT keys down and then hit ENTER

  8. #8
    Registered User
    Join Date
    01-20-2010
    Location
    United States
    MS-Off Ver
    Excel 2007
    Posts
    8

    Re: Constructing a formula that counts distinct words in a single cell

    Now the Error message says, "You've entered too many arguments for this function."

  9. #9
    Forum Expert NBVC's Avatar
    Join Date
    12-06-2006
    Location
    Mississauga, CANADA
    MS-Off Ver
    2003:2010
    Posts
    34,898

    Re: Constructing a formula that counts distinct words in a single cell

    Did you copy it exactly? I just copied/pasted back to my workbook to verify and it was okay.

  10. #10
    Forum Expert daddylonglegs's Avatar
    Join Date
    01-14-2006
    Location
    England
    MS-Off Ver
    2016
    Posts
    14,675

    Re: Constructing a formula that counts distinct words in a single cell

    Quote Originally Posted by NBVC View Post
    Try:

    =COUNT(FIND(ROW(INDIRECT({"1:32"})),Jan!G2))

    Hold the CTRL and SHIFT keys down and then hit ENTER
    That won't work here because it won't differentiate between a single 1 and a 1 in 11, 21 or 31, so for this data

    6, 17, 25, 32

    you'll get a count of 9 because it will count 1, 2, 3, 5, 6, 7, 17, 25 and 32

    Assuming only numbers between 1 and 32 separated by comma+space with no extra characters at the start or end you could use this version

    =COUNT(FIND(" "&ROW(INDIRECT("1:32"))&","," "&Jan!G2&","))

    confirmed with CTRL+SHIFT+ENTER

    or to avoid CSE

    =SUMPRODUCT(ISNUMBER(FIND(" "&ROW(INDIRECT("1:32"))&","," "&Jan!G2&","))+0)
    Last edited by daddylonglegs; 01-20-2010 at 05:33 PM.

  11. #11
    Forum Expert NBVC's Avatar
    Join Date
    12-06-2006
    Location
    Mississauga, CANADA
    MS-Off Ver
    2003:2010
    Posts
    34,898

    Re: Constructing a formula that counts distinct words in a single cell

    I obviously should have tested it better... not thinking

  12. #12
    Registered User
    Join Date
    01-20-2010
    Location
    United States
    MS-Off Ver
    Excel 2007
    Posts
    8

    Re: Constructing a formula that counts distinct words in a single cell

    Now it is returning the result: 1

  13. #13
    Forum Expert NBVC's Avatar
    Join Date
    12-06-2006
    Location
    Mississauga, CANADA
    MS-Off Ver
    2003:2010
    Posts
    34,898

    Re: Constructing a formula that counts distinct words in a single cell

    If you used the COUNT formula you must hold the CTRL and SHIFT keys down after you type or paste in the formula and then hit ENTER...

    otherwise, use the SUMPRODUCT() version and just hit ENTER.

  14. #14
    Registered User
    Join Date
    01-20-2010
    Location
    United States
    MS-Off Ver
    Excel 2007
    Posts
    8

    Re: Constructing a formula that counts distinct words in a single cell

    Oh my goodness, you have just made my life 20x easier! Thanks so much!!!

+ Reply to Thread

Thread Information

Users Browsing this Thread

There are currently 1 users browsing this thread. (0 members and 1 guests)

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