compare words in text with a list of comma separated terms

davidmyers

Board Regular
Joined
Jan 29, 2017
Messages
88
Office Version
  1. 2016
Platform
  1. Windows
Hi I'm looking for a vba solution for the following:
Sheet1 Col A: Group Name
Col B: list of comma separated terms (for this Group)


Sheet2 Col A: text string
Col B: Group Name


I need to loop thru all the Groups in Sheet 1 and check if any of the terms in Sheet1 ColB appear in the text in Sheet2 Col A, if a match is found then copy the Group Name (Sheet1 ColA) to Sheet2 ColB and continue with the next cell in Sheet2 Col A.
What I have so far is:

Code:
For each cell in Sheet2ColA
     For each Group in Sheet1ColA
        If  (word in Sheet2ColA  is found in Sheet1ColB) Then
             Copy Sheet1ColA (Group Name) to Sheet2ColB
             Exit For
        End If
    Next Group
Next  cell in Sheet2ColA

Need help to write the VBA
Thanks
David
 
Last edited:

Excel Facts

Highlight Duplicates
Home, Conditional Formatting, Highlight Cells, Duplicate records, OK to add pink formatting to any duplicates in selected range.
Hi David... good name. Are there duplicates in the groups or terms? Where on sheet2 do U want to put the group name.. beside the found term or terms? Dave
 
Upvote 0
Hi David... good name. Are there duplicates in the groups or terms? Where on sheet2 do U want to put the group name.. beside the found term or terms? Dave
Just to add to NdNoviceHlp's questions... can the text in a single cell on Sheet2 in Column A ever contain terms from more than one of Sheet1's groups and, if so, how should those multiple group names be shown?
 
Upvote 0
Hi Dave, Thanks for getting back to me.
There are no duplicates in the groups or terms. As soon as a match is found between the lists in Sheet2 and the text in Sheet1 then I want the group name for that list to appear in Sheet2ColB - next to the text in ColA, and move on to the next cell in Sheet2ColA.
I don't know how to proccess the comma separated list.

Rick just saw your question, each text cell has only group name as soon as a match is found I copy the Group Name and move on.

Thanks for your help
David
 
Last edited:
Upvote 0
Hi Dave, Thanks for getting back to me.
There are no duplicates in the groups or terms. As soon as a match is found between the lists in Sheet2 and the text in Sheet1 then I want the group name for that list to appear in Sheet2ColB - next to the text in ColA, and move on to the next cell in Sheet2ColA.
I don't know how to proccess the comma separated list.

Rick just saw your question, each text cell has only group name as soon as a match is found I copy the Group Name and move on.
One more question...

You did not show us examples of your terms and text, so we need to know, is it possible for a term on Sheet1 to be embedded within a word in the text on Sheet2? For example, if one of your terms on Sheet1 was "other" and the text on Sheet2 contained the word "motherhood", a simple search would find the word other inside of the word motherhood whereas a more exacting and noticeably slower process could avoid such happenings. So, are your terms and text such that this kind of embedded terms within text can never occur?
 
Upvote 0
That scenario is quite possible, however I'n only looking for matches on complete words ie. delimited by spaces

Thanks
David
 
Upvote 0
How about
Code:
Sub MatchWordInsert()

   Dim Cl As Range
   Dim Cnt As Long
   Dim Ws1 As Worksheet
   Dim Ws2 As Worksheet
   
   Set Ws1 = Sheets("Sheet1")
   Set Ws2 = Sheets("Sheet2")
   With CreateObject("scripting.dictionary")
      .CompareMode = vbTextCompare
      For Each Cl In Ws1.Range("B2", Ws1.Range("B" & Rows.Count).End(xlUp))
         For Cnt = LBound(Split(Cl, ",")) To UBound(Split(Cl, ","))
            If Not .exists(Trim(Split(Cl, ",")(Cnt))) Then .Add Trim(Split(Cl, ",")(Cnt)), Cl.Offset(, -1).Value
         Next Cnt
      Next Cl
      For Each Cl In Ws2.Range("A2", Ws2.Range("A" & Rows.Count).End(xlUp))
         If .exists(Cl.Value) Then Cl.Offset(, 1).Value = .Item(Cl.Value)
      Next Cl
   End With
   
End Sub
 
Upvote 0
Hi Fluff, Thanks for this.
My vba coding skills are not to strong, wanted to uploaded an example workbook or screen shots to confirm we're talking about the same thing but didn't succeed, how do I do that?
 
Upvote 0
Assuming you data starts on Row 1 on both sheets, see if this macro works for you...
Code:
[table="width: 500"]
[tr]
	[td]Sub MatchTerms()
  Dim R1 As Long, R2 As Long, Terms() As String
  Dim V As Variant, Groups As Variant, TermList As Variant, Text As Variant, Result As Variant
  Groups = Sheets("Sheet1").Range("A1", Sheets("Sheet1").Cells(Rows.Count, "A").End(xlUp))
  TermList = Sheets("Sheet1").Range("B1", Sheets("Sheet1").Cells(Rows.Count, "B").End(xlUp))
  Text = Sheets("Sheet2").Range("A1", Sheets("Sheet2").Cells(Rows.Count, "A").End(xlUp))
  ReDim Result(1 To UBound(Text), 1 To 1)
  For R1 = 1 To UBound(TermList)
    For Each V In Split(TermList(R1, 1), ",")
      For R2 = 1 To UBound(Text)
        If Len(Result(R2, 1)) = 0 Then
          If " " & UCase(Text(R2, 1)) & " " Like "*[!A-Z]" & UCase(Trim(V)) & "[!A-Z]*" Then Result(R2, 1) = Groups(R1, 1)
        End If
      Next
    Next
  Next
  Sheets("Sheet2").Range("B1").Resize(UBound(Result)) = Result
End Sub[/td]
[/tr]
[/table]
 
Upvote 0

Forum statistics

Threads
1,224,823
Messages
6,181,175
Members
453,021
Latest member
Justyna P

We've detected that you are using an adblocker.

We have a great community of people providing Excel help here, but the hosting costs are enormous. You can help keep this site running by allowing ads on MrExcel.com.
Allow Ads at MrExcel

Which adblocker are you using?

Disable AdBlock

Follow these easy steps to disable AdBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the icon in the browser’s toolbar.
2)Click on the "Pause on this site" option.
Go back

Disable AdBlock Plus

Follow these easy steps to disable AdBlock Plus

1)Click on the icon in the browser’s toolbar.
2)Click on the toggle to disable it for "mrexcel.com".
Go back

Disable uBlock Origin

Follow these easy steps to disable uBlock Origin

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back

Disable uBlock

Follow these easy steps to disable uBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back
Back
Top