If cell contains text, VLOOKUP that text

cogough

New Member
Joined
Oct 31, 2016
Messages
6
Hi all,
Apologies if this has been answered somewhere else but if it is, I can't find it.

I'm setting up a budget spreadsheet where I download all of my transactions from my bank and run a little macro that automatically categorizes all of my transactions based on an existing table. So for example, if a transaction description is "Debit Card Purchase - KROGER 800 GLENWOOD RD", I want the next column to pull in Kroger as the description and the column after to pull in Groceries. For now, I'm just looking for the actual formula that will accomplish before starting the macro.

I've found what I originally thought were solutions using LOOKUP/SEARCH/ISNUMBER but that seems to be the opposite of what I'm trying to do.

Below is a simple version of what I need. The formula I'm looking for would be entered in the second and third columns.

Thanks in advance!

Bank Transaction DescriptionClean DescriptionCategory
Withdrawal from PENNYMAC ACH PYTSPennyMacMortgage
Debit Card Purchase - RELISH SALON 924RelishHaircut
Debit Card Purchase - KROGER FUEL CTRKrogerFuel
Digital Card Purchase - FANDANGO COM FANDANGO COM CAFandangoEntertainment
Debit Card Purchase - CVS/PHARM 07336--520 BCVSPharmacy
Debit Card Purchase - REGAL CINEMAS HLYWD 24Regal CinemasEntertainment
Debit Card Purchase - AMAZON MKTPLACE PMTS W WWW AMAZON C WAAmazonMisc
Debit Card Purchase - SQU SQ DRIP COFFEE SHDripFood
Debit Card Purchase - PP FOODA CHICAGO ILFoodaFood
Debit Card Purchase - KROGER 800 GLENWOOD RDKrogerGroceries
Debit Card Purchase - KROGER 150 MAIN STKrogerGroceries
Debit Card Purchase - KROGER 233 DECATUR AVEKrogerGroceries

<tbody>
</tbody>

cvsCVSPharmacy
fandangoFandangoEntertainment
kroger fuelKrogerFuel
pennymacPennyMacMortgage
relishRelishHaircut

<tbody>
[TD="bgcolor: #4349aa"] Lookup [/TD]
[TD="bgcolor: #4349aa"] Clean Description [/TD]
[TD="bgcolor: #4349aa"] Category [/TD]

[TD="bgcolor: #d6d7ff"] amazon [/TD]
[TD="bgcolor: #d6d7ff"] Amazon [/TD]
[TD="bgcolor: #d6d7ff"] Misc [/TD]

[TD="bgcolor: #d6d7ff"] drip coffee [/TD]
[TD="bgcolor: #d6d7ff"] Drip [/TD]
[TD="bgcolor: #d6d7ff"] Food [/TD]

[TD="bgcolor: #d6d7ff"] fooda [/TD]
[TD="bgcolor: #d6d7ff"] Fooda [/TD]
[TD="bgcolor: #d6d7ff"] Food [/TD]

[TD="bgcolor: #d6d7ff"] kroger [/TD]
[TD="bgcolor: #d6d7ff"] Kroger [/TD]
[TD="bgcolor: #d6d7ff"] Groceries [/TD]

[TD="bgcolor: #d6d7ff"] regal cinema [/TD]
[TD="bgcolor: #d6d7ff"] Regal Cinemas [/TD]
[TD="bgcolor: #d6d7ff"] Entertainment [/TD]

</tbody>
 

Excel Facts

Excel Can Read to You
Customize Quick Access Toolbar. From All Commands, add Speak Cells or Speak Cells on Enter to QAT. Select cells. Press Speak Cells.
This looks somewhat tricky.

For example, you have two Clean Description items that pull in as "Kroger". Both contain "kroger" in the Lookup field. However, the Category column is differentiated by whether the "kroger" is followed by "fuel". Simple enough to rectify for the Lookup table, but when you get back to your transaction-level detail, to determine whether or not a "kroger" value is actually "Food" or "Groceries" category, you need two checks. This is not the case for the rest of your table. Furthermore, if you had a third category from the same provider (e.g. "kroger furniture") then you would need a third check. Based on the subset of data you provided as example, I do not think there is a good/reliable formula you can write to handle this.

Perhaps you need to expand your categories so that each Lookup can be uniquely identified. In other words, you should have a category for "kroger fuel" as you do now, then "kroger 500", "kroger 800", and any other Kroger stores you patronize for groceries identified by the address. As it stands, any standalone "kroger" category by itself will also match "kroger fuel", which is not what you want.

Does your current little macro work as intended? Can you post that code?
 
Last edited:
Upvote 0
In B2 enter and copy down:

=LOOKUP(9.99999999999999E+307,SEARCH(" "&INDEX(Table,0,1)&" "," "&A2&" "),INDEX(Table,0,2))

In C2 enter and copy down:

=VLOOKUP($B2,Table,3,0)

where Table is the colored table you posted, which contains amazon >> Amazon >> Misc, etc.
 
Upvote 0
Aladin, that was brilliant! I would have never been able to come up with that. Thanks

I just had to remove the two spaces before and after the first index because after evaluating it, I found that it was looking for " cvs " but the cell contained " cvs/". After that tweak, it worked on every cell. Here's my final formula.
=LOOKUP(9.99999999999999E+307,SEARCH(INDEX(Table1,0,1)," "&A6&" "),INDEX(Table1,0,2))

iliace, I knew things like Kroger would be a problem but now that I have the basic formula, I can work around that. When I create the macro, I think I'll just add a function to find/replace those problem children so Kroger Fuel becomes Krg Fuel before doing the formula. Those exceptions should be few and far between so it'll be manageable.
 
Upvote 0

Forum statistics

Threads
1,224,823
Messages
6,181,177
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