+ Reply to Thread
Results 1 to 13 of 13

Finding the hidden words in strings of letters

  1. #1
    Forum Contributor
    Join Date
    03-16-2007
    Location
    Berlin, Germany
    MS-Off Ver
    Excel 2007
    Posts
    202

    Finding the hidden words in strings of letters

    Hi! Can someone help me?

    I have a list of strings of letters (column A):

    YDHEIHGKCEWEC
    RIGJSTARSDSFDH
    JDSUNDHXSUNFL
    HFYEIDGSKQWK
    CBVNZTMOONWRH
    DASFRERTYBJHX
    JDIFJGFFGDFFPG
    LKJHMOONDFJHU


    And then a list of words (column B):
    SUN
    MOON
    STAR

    The words from the second list are hidden in the strings in the first list (I marked them red). The words can be hidden or more than once in the whole list, or even in the same string.

    I need a formula in column C which will go through the whole list of words B, and for each of the words, return: how many times the word is hidden in the whole list, and in which string(s).

    Any ideas?

    Thanks!!
    Last edited by Hitch75; 07-14-2011 at 04:51 AM.

  2. #2
    Forum Moderator zbor's Avatar
    Join Date
    02-10-2009
    Location
    Croatia
    MS-Off Ver
    365 ProPlus
    Posts
    15,596

    Re: Finding the hidden words in strings of letters

    There is simple solution for words and different words within on word.

    But it doesn't count same words within one word.
    Attached Files Attached Files
    Last edited by zbor; 07-13-2011 at 05:42 AM.

  3. #3
    Forum Contributor
    Join Date
    03-16-2007
    Location
    Berlin, Germany
    MS-Off Ver
    Excel 2007
    Posts
    202

    Re: Finding the hidden words in strings of letters

    Hmm thanks... but maybe someone knows how to register the double appearances too?

  4. #4
    Valued Forum Contributor
    Join Date
    10-13-2010
    Location
    Sunderland, England
    MS-Off Ver
    Excel 2007 (Home) / 2003 (Work)
    Posts
    740

    Re: Finding the hidden words in strings of letters

    Expanding on Zbor's idea, you could use:

    =COUNTIF(A:A,"*"&B1&"*")+COUNTIF(A:A,"*"&B1&"*"&B1&"*")

    to include where a word appears twice in a line, or using the same theory:

    =COUNTIF(A:A,"*"&B1&"*")+COUNTIF(A:A,"*"&B1&"*"&B1&"*")+COUNTIF(A:A,"*"&B1&"*"&B1&"*"&B1&"*")

    to count up to three appearances per line. And so on and so forth, until the formula gets too big for Excel.

    I guess it depends on the length of your strings as to if this will be enough, or if you'll require something more complex?

  5. #5
    Forum Expert
    Join Date
    12-03-2009
    Location
    Florence, Italy
    MS-Off Ver
    Excel 2019
    Posts
    1,796

    Re: Finding the hidden words in strings of letters

    Hi,

    an attempt: in C3 waht you are looking to count

    =(SUMPRODUCT(--LEN($A$3:$A$1000))-SUMPRODUCT(--LEN(SUBSTITUTE($A$3:$A$1000,C3,""))))/LEN(C3)

    Hope it helps
    Attached Files Attached Files

  6. #6
    Forum Expert
    Join Date
    12-03-2009
    Location
    Florence, Italy
    MS-Off Ver
    Excel 2019
    Posts
    1,796

    Re: Finding the hidden words in strings of letters

    Hi All,

    I've dried up a little the SUMPRODUCT


    =SUMPRODUCT(LEN($A$3:$A$1000)-LEN(SUBSTITUTE($A$3:$A$1000,C3,"")))/LEN(C3)

    I'm sure there are better ways


    Hope it helps
    Attached Files Attached Files

  7. #7
    Forum Contributor
    Join Date
    03-16-2007
    Location
    Berlin, Germany
    MS-Off Ver
    Excel 2007
    Posts
    202

    Re: Finding the hidden words in strings of letters

    CANAPONE, your formula works perfectly. Thanks!!
    Thanks to others too.

    The only thing is, I said I also wanted the formula to show in which string(s) the word(s) are. That can also be a new formula, apart from this one.
    To make it easier, we could add a column with marks S1, S2, S3 to numerize each string, and then the formula should return, "S3,S5" if the words are hidden in strings S3 and S5.

  8. #8
    Forum Expert
    Join Date
    12-03-2009
    Location
    Florence, Italy
    MS-Off Ver
    Excel 2019
    Posts
    1,796

    Re: Finding the hidden words in strings of letters

    Hi,

    the following formula could be an example to visually get the positions of "SUN" "MOON".

    =IF(ISERROR(SMALL(IF(ISNUMBER(FIND($C3,$A$3:$A$12,1)),ROW($A$3:$A$12)),COLUMN(A1))),"","A"&SMALL(IF(ISNUMBER(FIND($C3,$A$3:$A$12,1)),ROW($A$3:$A$12)),COLUMN(A1)))
    All the yellow formulae are array formule and hav to be confirmed with control+shift+enter.

    Even If a string contains "SUN" twice or more, the formula gives back its position once.

    Maybe the attachment is more clear.

    Regards
    Attached Files Attached Files
    Last edited by canapone; 07-13-2011 at 12:39 PM.

  9. #9
    Forum Contributor
    Join Date
    03-16-2007
    Location
    Berlin, Germany
    MS-Off Ver
    Excel 2007
    Posts
    202

    Re: Finding the hidden words in strings of letters

    It works... But I actually really need it with marks such as "S1, S2", not cell references
    Is there any way to fix the same formula so that it returns these marks?

    I hope you understand me, I mean this:

    S1 JGDFJGASGD
    S2 KJHSKJHKLK
    S3 LKHJMOONQQ

    MOON 1 S3

  10. #10
    Forum Expert
    Join Date
    12-03-2009
    Location
    Florence, Italy
    MS-Off Ver
    Excel 2019
    Posts
    1,796

    Re: Finding the hidden words in strings of letters

    Hi, an attempt to get S1 S5 ...

    =IF(ISERROR(SMALL(IF(ISNUMBER(FIND($C3,$A$3:$A$12,1)),ROW($A$3:$A$12)),COLUMN(A1))),"","S"&SMALL(IF( ISNUMBER(FIND($C3,$A$3:$A$12,1)),ROW($A$3:$A$12)),COLUMN(A1))-2)

    Regards
    Attached Files Attached Files

  11. #11
    Forum Contributor
    Join Date
    03-16-2007
    Location
    Berlin, Germany
    MS-Off Ver
    Excel 2007
    Posts
    202

    Re: Finding the hidden words in strings of letters

    The attempt works

    Thanks a lot!!

  12. #12
    Forum Expert
    Join Date
    12-03-2009
    Location
    Florence, Italy
    MS-Off Ver
    Excel 2019
    Posts
    1,796

    Re: Finding the hidden words in strings of letters

    Hi, thanks for the feedback.

    If you'd need, you could substitute FIND -it's case sensitive, if I remember well- with SEARCH to work with a less touchy formula.

    Regards

  13. #13
    Forum Contributor
    Join Date
    03-16-2007
    Location
    Berlin, Germany
    MS-Off Ver
    Excel 2007
    Posts
    202

    Re: Finding the hidden words in strings of letters

    It doesn't matter in my case.. Thanks!

+ 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