Categorizing Formula

Austin Lang

New Member
Joined
Sep 10, 2021
Messages
46
Office Version
  1. 365
  2. 2021
  3. 2019
Platform
  1. Windows
Hey all,

I am working on a budgeting sheet that I created to get a hold on my finances. I created a formula that will auto-categorize my transactions when I paste in my transactions. Here is that formula..

=IF(ISBLANK(M5),"",IFERROR(INDEX($V$50:$V$153,MATCH(TRUE,ISNUMBER(SEARCH($U$50:$U$153,$M5)),0)),"Unknown"))

Here are some snips of the transactions and some assigned categories..

1654728054779.png
1654727274775.png


When the categories table grows, I have the extend the range in the above formula to look at the entire table. It becomes tedious doing every month when I have to add different keywords. Ideally, I would like to add 10 lines to the referenced list, but only need 2 of them. That way, I don't have to edit the formula next time. The hiccup is that the formula will not return "Unknown" unless the range in the formula has data all the way to the end. If there is any blank spaces in the table, it just returns "0".

1654727845739.png


I have a feeling I am over thinking this, but how do I add to my formula to return "Unknown" regardless if my keywords table has data all the way to where I have specified or not?

Thanks in advance.
 

Attachments

  • 1654727796276.png
    1654727796276.png
    12.7 KB · Views: 3

Excel Facts

Does the VLOOKUP table have to be sorted?
No! when you are using an exact match, the VLOOKUP table can be in any order. Best-selling items at the top is actually the best.
Here is one idea since you appear to be using Excel 365. Convert your lookup table to a formal table (click in table and hit Ctrl-t and indicate you have headings...give the columns heading names first) then use structured references in your formula. You can add to the bottom of this reference table without needing to update the range in the formula. And then use the FILTER function to filter out any blanks.
MrExcel_20220608.xlsx
ABCDEFG
1
2DateVendorAmtCatVendorCategory
35/2/2022Chili's 5/1100UnknownMcDonald'sFood
45/2/2022McDonald's F4410FoodExxonMobilCar Expenses
55/2/2022Target 5/160MiscellaneousTargetMiscellaneous
65/2/2022ExxonMobil 97390Car Expenses
7 
8 
9
Sheet4
Cell Formulas
RangeFormula
D3:D8D3=IF(B3="","",FILTER(Table1[Category],(Table1[Vendor]<>"")*(ISNUMBER(SEARCH(Table1[Vendor],B3))),"Unknown"))
 
Upvote 0

Forum statistics

Threads
1,213,544
Messages
6,114,249
Members
448,556
Latest member
peterhess2002

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