VBA Solution to Search Text and Return Desired Result

plk0507

New Member
Joined
Dec 15, 2021
Messages
18
Office Version
  1. 365
Platform
  1. Windows
Hi,

First-time poster so I want to say thank you in advance for looking at my issue. Below is a sample from my worksheet that is actually hundreds of thousands of lines long.

I'm looking for a solution to search columns J, K, and L for the values in column Y (column y is actually 5-6 thousand lines long). And if it finds the value, return it to column M, separated by a comma.

I've been using the following formula: =TEXTJOIN(", ", TRUE, IF(COUNTIF(J2:L2, "*"&$Y$2:$Y$9&"*"), $Y$2:$Y$9, ""))

My issue with that formula is it also returns partial matches. For example, look at the result in M3. It returned W269 simply because it's a partial match to W2690. On a file with 900 thousand lines, that partial match could repeat itself a few thousand times, and manually fixing it can take days. My other issue is running that formula can take a couple of hours.

My question is, is there a VBA solution to searching this data that will return the desired result without the partial matches? Thank you for your help, I sincerely appreciate it.



Book1.xlsx
ABCDEFGHIJKLMNOPQRSTUVWXY
1Aircraft TypeTail NumberJCNWCE IDWUCHow MalAction TakenWhen Discovered CodeType Maint CodeCorrective ActionDiscrepancyWCE NarrativeHarnessRDIStart DateStop DateLaborBaseUnits ProducedHow Mal ClassBlock NumberHarness Number
2F016D 8900002171 1515502761 62000799XFBVHF OPS CHK C/WVHF AUDIO HARNESS W1654 PART NUMBER H16DW1654-504,W1644 PART NUMBER H16DW1644-514 AND W1844 PART NUMBER H16DW1844-300 REQUIRE REPLACEMENT.VHF AUDIO HARNESS W1654 PART NUMBER H16DW1654-504,W1644 PART NUMBER H16DW1644-514 AND W1844 PART NUMBER H16DW1844-300 REQUIRE REPLACEMENT.W1644, W1654, W184442799.7142799.752KUNSAN1640W1644
3F016D 9000000783 2035105340 630006FSRRECOUP HOURS FOR: SOLDER NEW WAFER ON TO WIRES TO REPAIR W1812-9154J424. PERFORM CONTINUITY CHECK TO ENSURE PROPER CONNECTIONSREF 1F-16CG-2-00GV-00-2***ADD TIME REQ, REF OP#91438*** NSFE FOUND DURING INSTALL OF HARNESS 16DW2690-501 BROKEN PINS WERE FOUND ON W1812-9154J424 T.O./FIG:REF 1F-16CG-2-00GV-00-2***ADD TIME REQ, REF OP#91438*** NSFE FOUND DURING INSTALL OF HARNESS 16DW2690-501 BROKEN PINS WERE FOUND ON W1812-9154J424 T.O./FIG:REF 1F-16CG-2-00GV-00-2W269, W1812, W2690441814418144.3HILL AFB UT1142W1654
4F016D 9000000783 2034904270 630006FSRSOLDER NEW WAFER ON TO WIRES TO REPAIR W1812-9154J424. PERFORM CONTINUITY CHECK TO ENSURE PROPER CONNECTIONSREF 1F-16CG-2-00GV-00-2NSFE FOUND DURING INSTALL OF HARNESS 16DW2690-501 BROKEN PINS WERE FOUND ON W1812-9154J424 T.O./FIG:REF 1F-16CG-2-00GV-00-2NSFE FOUND DURING INSTALL OF HARNESS 16DW2690-501 BROKEN PINS WERE FOUND ON W1812-9154J424 T.O./FIG:REF 1F-16CG-2-00GV-00-2W269, W1812, W269044179441796HILL AFB UT1142W1844
5F016D 8900002166 1505674072 64000799XDDSEE NEW JCN 161896706 FOR UPDATED JOBCOM 2 RADIO TRANSMITS SQUEAL/TONES WHEN MIC IS KEYED, IF VOLUME KNOB IS PAST 3:00 POSITION. VOLUME ANY LOWER AND COM 2 IS INAUDIABLEJOB CREATED TO ORDER AND REPLACE VHF AUDIO HARNESS W1654 PART NUMBER H16DW1654-504,W1644 PART NUMBER H16DW1644-514 AND W1844 PART NUMBER H16DW1844-300.W1644, W1654, W184442563.2542563.292KUNSAN1640W269
6F016D 8800000170 2108891708 69B9870RBBW2690-204-20 R2 IAW 1F-16CG-2-00GV-00-2 SECTION 14PANEL 3434 & 3436 REMOVED TO FOM SEE JCN 210550032001W2690-204-20 SHOOTS OPEN FROM RPS 2382P2/1 TO LVT 2382P12W269, W26902382P12, 2382P2/144286.7144286.731EGLIN AFB FL1140W1812
7F016D 8800000170 21067022814 69B98308RBBFILL PORT HARNESS R2 IAW 1F-16CG-2-00GV-00-2 PARA 14.7MIDS 006,012,029,031,035,056,074,075 MFL'S. TACAN WORKED FINEH16DW2693P4/1 REMOVED FOR REPLACEMENTW269, W269344279.7944280.1324EGLIN AFB FL1140W2690
8F016D 8900002162 21063012810 69B00800SFBREINSTALLED CABLE H16DW2682-600 IAW (PARA 14.8 00GV-2)GUN REQ REM FOR JAMREMOVED CABLE H16DW2682-600 TO FOMW268, W268244263.6744263.712HOLLOMAN1642W268
9F016D 9000000783 2035105370 69000800SSRRECOUP HOURS FOR: INSTALL WIRE HARNESS 16DW2690-501 IN GUN DRUM IAW 16D40730.DOCUMENT STEPS AND TIME OF EACH STEP ON ATTACHED 959***ADD TIME REQ, REF OP#91427*** NSFE WIRE HARNESS 16DW2690-501 FOUND UNINSTALLED. T.O./FIG:IAW 16D40730***ADD TIME REQ, REF OP#91427*** NSFE WIRE HARNESS 16DW2690-501 FOUND UNINSTALLED. T.O./FIG:IAW 16D40730W269, W269044181441812.1HILL AFB UT1642W2682
10F016D 9000000783 2034904290 69000800SSRINSTALL WIRE HARNESS 16DW2690-501 IN GUN DRUM IAW 16D40730.DOCUMENT STEPS AND TIME OF EACH STEP ON ATTACHED 959NSFE WIRE HARNESS 16DW2690-501 FOUND UNINSTALLED. T.O./FIG:IAW 16D40730NSFE WIRE HARNESS 16DW2690-501 FOUND UNINSTALLED. T.O./FIG:IAW 16D40730W269, W269044179441794HILL AFB UT1642
11F016D 8900002167 2007221673 69B0020RFBR2 HARNESS IAW 1F-16CG-2-00GV-00-2 CHAPTER 14238282 P1/4 SMASHED, REQUIRES REPLACEMENTW2690-; 2382P3/3 & 2382P6 INNER WIRE EXPOSED REQUIRE REPLCMENT; 2382P2/1 MISSING GRNDING FSTNER AND 2382P3/3 WORN GRNDING FSTNER NUT REMAIN LOOSE AFTER TIGHTENING PN(H16DW2690-501)W269, W26902382P3/3, 2382P2/1, 2382P643909.543909.8324TULSA1142
Sheet2
 

Excel Facts

Create a chart in one keystroke
Select the data and press Alt+F1 to insert a default chart. You can change the default chart to any chart type
Hi buddy,

you can use InStr function to find Perfect Match in string or something similar, you can use Like operator with pattern and wildcard.

something like this :

Untitled.png


Insert this code in module :

VBA Code:
Option Explicit

Function SEARCHHARNESS() As String
    Dim ws As Worksheet: Set ws = ThisWorkbook.Sheets("Sheet1")
    Dim i As Long
    Dim last As Long
    Dim stringBuilder As String
    
    last = ws.Range("B" & Rows.Count).End(xlUp).Row
    stringBuilder = vbNullString
    
    For i = 1 To last
        If InStr(1, ws.Range("A" & Split(Application.ThisCell.Address, "$")(2)).Value, ws.Range("B" & i).Value, 1) Then
            If Len(stringBuilder) > 0 Then
                stringBuilder = stringBuilder & ", " & ws.Range("B" & i).Value
            Else
                stringBuilder = ws.Range("B" & i).Value
            End If
        End If
    Next i
    
    If Len(stringBuilder) < 1 Then stringBuilder = "Not Found"
    SEARCHHARNESS = stringBuilder
End Function

In your worksheet, select column C1 and in formula bar type this =SEARCHHARNESS() or in Formula Tab, click insert function, and choose SEARCHHARNESS

Play around with that code and modification to your need, good luck.
 
Upvote 0
I'm sorry, this is with little fix :

VBA Code:
Option Explicit

Function SEARCHHARNESS() As String
    Dim ws As Worksheet: Set ws = ThisWorkbook.Sheets("Sheet1")
    Dim i As Long
    Dim last As Long
    Dim stringBuilder As String
    
    last = ws.Range("B" & Rows.Count).End(xlUp).Row
    stringBuilder = vbNullString
    
    For i = 1 To last
        If InStr(1, ws.Range("A" & Split(Application.ThisCell.Address, "$")(2)).Value, ws.Range("B" & i).Value, 1) Then
            If stringBuilder <> vbNullString Then
                stringBuilder = stringBuilder & ", " & ws.Range("B" & i).Value
            Else
                stringBuilder = ws.Range("B" & i).Value
            End If
        End If
    Next i
    
    If stringBuilder = vbNullString Then stringBuilder = "Not Found"
    SEARCHHARNESS = stringBuilder
End Function
 
Upvote 0
Thank you for the reply.

For my example above, I modified your code to:
1639603571247.png


I get a #VALUE! error when I put =SEARCHHARNESS() in a column
 
Upvote 0
I did a better replication to make the data look like your example. It worked, but here are the results.
1639604264911.png


For example, look in C5. W269 is returned simply because it's part of W2690-204-20. My desired result would only return W2690. However, it ran it instantly.
 
Upvote 0
I did a better replication to make the data look like your example. It worked, but here are the results.
View attachment 53468

For example, look in C5. W269 is returned simply because it's part of W2690-204-20. My desired result would only return W2690. However, it ran it instantly.

Look at B4, you put W269 on criteria, of course it will counted right?, if you don't want W269 counted then don't put that on criteria column (in this case, column B).

However, you get error #VALUE because you had done something wrong in your modification code, in this line :

Code:
InStr(1, ws.Range("J:L" & Split(Application.ThisCell.Address, "$")(2)).Value, ws.Range("Y" & i).Value, 1)

it should be :

VBA Code:
If InStr(1, ws.Range("J" & Split(Application.ThisCell.Address, "$")(2)).Value, ws.Range("Y" & i).Value, 1) _
Or InStr(1, ws.Range("K" & Split(Application.ThisCell.Address, "$")(2)).Value, ws.Range("Y" & i).Value, 1) _
Or InStr(1, ws.Range("L" & Split(Application.ThisCell.Address, "$")(2)).Value, ws.Range("Y" & i).Value, 1) Then
    'The rest of code'
End If
End If
 
Last edited:
Upvote 0
Yes, W269 is on the list. So, W269 and W2690 are both on the list. But in the search example, "W2690-204-20 R2 IAW 1F-16CG-2-00GV-00-2 SECTION 14" W269 is a partial match.

Also, can I tell the code to search more than one column at a time?

Thank you!
 
Upvote 0
Modifying the lines to J, K, and L allowed for searching each column. Thank you!
 
Upvote 0

Forum statistics

Threads
1,223,893
Messages
6,175,240
Members
452,621
Latest member
Laura_PinksBTHFT

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