Categorize Items in a table against matching text in another table with partial matches.

mvulc

New Member
Joined
Mar 22, 2015
Messages
3
First of all thank you for taking the time to read my question, and provide an answer if possible.
My apologies if this is already answered on the forum, I did search for it but could not find how to do this sort of match either with either a vlookup or index match, as in my case I'm searching for the existence of any one of a number of values.

Here's what I'm trying to accomplish.

In the table below, assume columns A,B,C are a table, and columns F,G are a separate table.
I want to fill in column C with the "ticket type" value as listed in column G, so long as there is a match for any of the values in column F in the text within column B.
So the results should be
C2 = "Backup Failure"
C3 = "Backup Failure"
C4 = "Restore Request"
C5 = "Ping Timeout"
C6 = "Hardware Failure"
C7 = "Hardware Failure"


[TABLE="class: grid, width: 737"]
<tbody>[TR]
[TD]Ticket[/TD]
[TD]Title[/TD]
[TD]Type[/TD]
[TD][/TD]
[TD][/TD]
[TD]Match Text[/TD]
[TD]Ticket Type[/TD]
[/TR]
[TR]
[TD="align: right"]1[/TD]
[TD]Backup Failure on Server A[/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD]Backup[/TD]
[TD]Backup Failure[/TD]
[/TR]
[TR]
[TD="align: right"]2[/TD]
[TD]Server B Failed Backup[/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD]Restore[/TD]
[TD]Restore Request[/TD]
[/TR]
[TR]
[TD="align: right"]3[/TD]
[TD]Restore Directory on Server C[/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD]Ping[/TD]
[TD]Ping Timeout[/TD]
[/TR]
[TR]
[TD="align: right"]4[/TD]
[TD]Ping Timeout Server D[/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD]Hard Drive[/TD]
[TD]Hardware Failure[/TD]
[/TR]
[TR]
[TD="align: right"]5[/TD]
[TD]Server D Failed Hard Drive[/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD]Failed Memory[/TD]
[TD]Hardware Failure[/TD]
[/TR]
[TR]
[TD="align: right"]6[/TD]
[TD]Server E Failed Memory[/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[/TR]
</tbody>[/TABLE]
 

Excel Facts

VLOOKUP to Left?
Use =VLOOKUP(A2,CHOOSE({1,2},$Z$1:$Z$99,$Y$1:$Y$99),2,False) to lookup Y values to left of Z values.
Here's a function that should do what you're after:

Code:
Public Function ticketType(matchText As Range, title As Range)
    Dim i As Integer
    i = 2
    For Each rng In matchText
        If InStr(UCase(title.Value), UCase(rng.Value)) Then
            ticketType = Range("G" & i)
        End If
        i = i + 1
    Next
End Function

Then use this formula in C2 and drag down:

Code:
=ticketType($F$2:$F$6,B2)
 
Upvote 0
...In the table below, assume columns A,B,C are a table, and columns F,G are a separate table.
I want to fill in column C with the "ticket type" value as listed in column G, so long as there is a match for any of the values in column F in the text within column B.
[...]

Define BigNum as referring to:

=9.99999999999999E+30

In C2 enter and copy down:

=LOOKUP(BigNum,SEARCH(" "&$F$2:$F$6&" "," "&B2&" "),$G$2:$G$6)
 
Upvote 0

Forum statistics

Threads
1,223,099
Messages
6,170,107
Members
452,302
Latest member
TaMere

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