VBA to search & fill out text in specific columns

Sia

New Member
Joined
Aug 28, 2024
Messages
7
Office Version
  1. 2019
Platform
  1. Windows
Hello,
Looking for assistance for the following topic:

I am trying to create a code. That code should check if cell "C2", sheet ''test", contains one or more words from sheet "Search Values".
If the code finds a match , it should copy the matching word and paste it on the next cell in column "D" ( without repeatable ones ). The code go through the whole column "C", cell by cell : C3,C4,C5 etc. , and paste the matching words in respective column next to (column D3,D4,D5).

Please check the attached images for reference.
I would like to thanks a lot in advance to anyone who is able to advise me.

Regards,
 

Attachments

  • Screenshot 2024-08-28 184316.png
    Screenshot 2024-08-28 184316.png
    63.5 KB · Views: 9
  • Exc 2024-08-28 185225.png
    Exc 2024-08-28 185225.png
    23.8 KB · Views: 9
  • Screenshot 2024-08-28 160330.png
    Screenshot 2024-08-28 160330.png
    55.5 KB · Views: 9

Excel Facts

Ambidextrous Undo
Undo last command with Ctrl+Z or Alt+Backspace. If you use the Undo icon in the QAT, open the drop-down arrow to undo up to 100 steps.
Try this


VBA Code:
Sub search_fill()
  Dim i As Long, k As Long
  Dim a As Variant, b As Variant, c As Variant
  Dim s As String
  
  a = Sheets("test").Range("C2", Sheets("test").Range("C" & Rows.Count).End(3)).Value
  b = Sheets("Search Values").Range("A1", Sheets("Search Values").Range("A" & Rows.Count).End(3)).Value
  ReDim c(1 To UBound(a, 1), 1 To 1)
  
  For i = 1 To UBound(a, 1)
    s = ""
    For k = 1 To UBound(b, 1)
      If InStr(1, a(i, 1), b(k, 1), vbTextCompare) > 0 Then s = s & b(k, 1) & Chr(10)
    Next
    If s <> "" Then c(i, 1) = Left(s, Len(s) - 1)
  Next
  Sheets("test").Range("D2").Resize(UBound(c, 1)).Value = c
End Sub
 
Upvote 0
Try this


VBA Code:
Sub search_fill()
  Dim i As Long, k As Long
  Dim a As Variant, b As Variant, c As Variant
  Dim s As String
 
  a = Sheets("test").Range("C2", Sheets("test").Range("C" & Rows.Count).End(3)).Value
  b = Sheets("Search Values").Range("A1", Sheets("Search Values").Range("A" & Rows.Count).End(3)).Value
  ReDim c(1 To UBound(a, 1), 1 To 1)
 
  For i = 1 To UBound(a, 1)
    s = ""
    For k = 1 To UBound(b, 1)
      If InStr(1, a(i, 1), b(k, 1), vbTextCompare) > 0 Then s = s & b(k, 1) & Chr(10)
    Next
    If s <> "" Then c(i, 1) = Left(s, Len(s) - 1)
  Next
  Sheets("test").Range("D2").Resize(UBound(c, 1)).Value = c
End Sub
Hello Mr DanteAmor,

I truly appreciate your help. Lots of thanks, be blessed, that is exactly what i need.

Regards!
 
Upvote 0

Forum statistics

Threads
1,221,310
Messages
6,159,176
Members
451,543
Latest member
cesymcox

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