+ Reply to Thread
Results 1 to 13 of 13

Searching for multiple words in a cell

  1. #1
    Registered User
    Join Date
    05-02-2011
    Location
    New York
    MS-Off Ver
    Excel 2003
    Posts
    7

    Searching for multiple words in a cell

    Hello,

    I'm trying to search for a list of words within a cell that contains text and have those words displayed in the column adjacent to it.

    For example:

    A1: The cat in the hat.
    A2: The dog in the hat.
    A3: The walrus in the hat.
    A4: The cat on the mat.
    A5: The cat and dog on the mat.

    B1:B5 contains the search terms I'm looking for:
    B1: Cat
    B2: Dog
    B3: Walrus
    B4: Hat
    B5: Mat

    I would like C1:C5 to show whether the search terms in B1:B5 are found in A1:A5, and then display those results (ie C1 should show 'cat and hat' and C2 should show 'dog and hat' and C5 should show 'cat, dog and mat').

    Currently I'm using =IF(COUNT(SEARCH({"Cat","Dog"},A1)),"Cat","") but this formula isn't particularly useful for my purposes since it is TRUE/FALSE rather than returning the actual search term.

    I would be very grateful for any help - thank you so much in advance!
    Last edited by NBVC; 05-04-2011 at 01:35 PM. Reason: Assumed solved based on rep given on last post.

  2. #2
    Registered User
    Join Date
    05-02-2011
    Location
    New York
    MS-Off Ver
    Excel 2003
    Posts
    7

    Re: How to search for multiple words in list and display results?

    It seems like there has been a similar question posted before in this thread: http://www.excelforum.com/excel-gene...text-cell.html

    but the functions provided "=LOOKUP(2,1/ISNUMBER(SEARCH($M$2:$M$10,$C2)),N$2:N$10)" and "=INDEX(N$2:N$10,MATCH(1,INDEX(SEARCH($M$2:$M$10,$C2),0),0))" are only capable of finding one match of the keyword (the first or the last). Is it possible to make these functions show all matches of the keywords?

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

    Re: Searching for multiple words in a cell

    Insert this code into your VB editor (Alt +F11, Insert|Module)

    Please Login or Register  to view this content.
    Then try formula in C1:

    =SUBSTITUTE(TRIM(ACONCAT(IF(ISNUMBER(MATCH("*"&$B$1:$B$5&"*",A1,0)),$B$1:$B$5,"")," "))," ",", ")

    confirmed with CTRL+SHIFT+ENTER not just ENTER and copy down.
    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.

  4. #4
    Registered User
    Join Date
    05-02-2011
    Location
    New York
    MS-Off Ver
    Excel 2003
    Posts
    7

    Re: Searching for multiple words in a cell

    Thank you so much for your very helpful reply! The vba worked perfectly for my example.

    I tried replicating this for a more complicated text - the US Constitution as an example but the results aren't so consistent. There's also a problem with the "0" and commas...since comma separators aren't necessary, I'm wondering if it would make the formula simpler if they were left out?

    I was actually quite skeptical before about whether excel had the power to do this type of search but your macro gave me a lot of confidence. If you have any further suggestions on this, I really would appreciate it!

    (I've attached my example file to this post)

    Edit: can't attach the file for some reason...
    Last edited by CU2011; 05-02-2011 at 05:29 PM.

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

    Re: Searching for multiple words in a cell

    Try condensing the file down or zipping it.

  6. #6
    Registered User
    Join Date
    05-02-2011
    Location
    New York
    MS-Off Ver
    Excel 2003
    Posts
    7

    Re: Searching for multiple words in a cell

    Here it is...

    I've never used macros before so please excuse my complete igorance of the subject! I'm wondering if it's possible to have the program identify exact matches of the keyword (such as capitalization)? Also, I noticed when I repeat this process with an extremely large file, say 3000 rows of text, the macro debugger pops out - is there a size limitation to the operation of this macro?

    Thank you so so much!
    Attached Files Attached Files

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

    Re: Searching for multiple words in a cell

    Try:

    Please Login or Register  to view this content.
    confirmed with CTRL+SHIFT+ENTER not just ENTER.

    This is case sensitive so if the string in column B has "congress" it will not pick up as a match to "Congress" in column C.

    I fixed it up so that you can still have comma delimiters, but it won't affect multi word entries like "Unites States".

    In some of your comments, you don't include "Congress" as being an expected match, like in D2.... but "Congress" does exist in B2.

    You also say that D15 should be blank, but I find that some of the words in column C do, in fact exist in B15 (and same with B16/D16 in case you are off by 1 row in your references in the comments).

    Also, I did copy the formula down to past 3000 rows and got no errors.... you just have to wait for the recalculating to finish as this is an array formula and can be slow when copied down thousands of rows.

  8. #8
    Registered User
    Join Date
    05-02-2011
    Location
    New York
    MS-Off Ver
    Excel 2003
    Posts
    7

    Re: Searching for multiple words in a cell

    This is absolutely brilliant - thank you so much!!

    Just one small question: I realized that if the area of reference in the keyword list is extended to the entire column, then the macro will return 0's in the results. Is this because the macro assumes the blank cells are also keywords that it needs to search?

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

    Re: Searching for multiple words in a cell

    If I extend the keywords list to include blanks, I don't get the 0's you say you are getting.

    Also, do not use whole columns are extra large ranges as this will slow down the recalculations considerably.

    You can create a dynamic range that "grows" with the addition or removal of keywords in the list.

    To do that go to Insert|Name|Define and enter the word Keywords in the names in this workbook field... and enter formula:

    Please Login or Register  to view this content.
    in the source field.

    Then change the formula in D2 to:

    Please Login or Register  to view this content.

  10. #10
    Registered User
    Join Date
    05-02-2011
    Location
    New York
    MS-Off Ver
    Excel 2003
    Posts
    7

    Re: Searching for multiple words in a cell

    Wonderful -it works perfectly! Thank you once again!

    One last question - how can I make it not make up plural forms ie: only Power, not Powers; or organ, not organization; or just US rather than USSC?

    Many thanks!

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

    Re: Searching for multiple words in a cell

    Do you mean you don't want it to pick up Power when the sentence contains Powers?

    If so, try:

    Please Login or Register  to view this content.
    CSE confirmed

    But note, that if you have words that have a symbol next to them like for example in this sentence: I am the best (President) of all time. Then it would not pick up President because it has a bracket before and/or after... I have used SUBSTITUTE functions to replace periods and commas, you can add more for the brackets, but there could be other symbols, like semi colons or colons, or exclamation points, or question marks, etc....

  12. #12
    Registered User
    Join Date
    05-02-2011
    Location
    New York
    MS-Off Ver
    Excel 2003
    Posts
    7

    Re: Searching for multiple words in a cell

    Ah I see what you mean...so I guess there isn't a way to get Excel to distinguish punctuation extensions of a word, such as, "The executive powers are vested in the President," vs letter extensions of a word, such as, "Presidential systems are a common form of constitutional government"?

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

    Re: Searching for multiple words in a cell

    If you noticed, I added a " " before and after the KeyWords named range. This forces the find to look for words that contain one of the keywords, but with a space before or after, this indicating to search for the exact word and not the word within a word like Presidential.... I accounted for the keyword potentially landing at the beginning or ending of a sentence by adding " " before and after the reference to B2... so it automatically adds a space at start and end of each sentence... then I incorporated a work around to replace commas and periods with nulls so that words next to those punctuations are captured... but if you have too many possible punctiations, it becomes more involved... in XL2003 you can only have up to 7 nested functions, so SUBSTITUTE for each possible symbol won't work...

    Maybe an easy alternative would be to copy column B into a new column and then use Edit|Replace from the Excel Menu to replace each possible symbol, one by one, then the formula should work (and you can remove the SUBSTITUTE(SUBSTITUTE(B2,".",""),",","") part and replace with just B2... well, in fact, you would need to change B2 to the new column reference... but you get the idea.

+ 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