Forum Discussion
Need an Excel Formula giving True or False based on the last word in the cell
- Feb 09, 2018
I tried another way. The following formula do not need CSE too.
=IF($D2="","",SUMPRODUCT(N(RIGHT($D2,LEN(Sheet2!$A$1:$A$5))=Sheet2!$A$1:$A$5))>0)
Patrick,
{=OR(IFERROR(LEN(A1)-SEARCH({"Avenue";"Road"},A1)+1={6;4},FALSE))}
- Patrick SilverwiseFeb 09, 2018Copper Contributor
Detlef Lewen
Thanks for the quick reply. I used your formula as an array and it worked perfectly. I entered
=IF(D2="","",OR(IFERROR(LEN(D2)-SEARCH({"Avenue";"Road"},D2)+1={6;4},FALSE)))
then Cntl+Shift+Enter and received the desired result:
Address1 Detlef Desired 123 Avenue TRUE TRUE 123 Road TRUE TRUE 123 Avenue Rd FALSE FALSE 123 Road Ave FALSE FALSE 123 Avenue Road TRUE TRUE 123 Road Avenue TRUE TRUE While it let me copy and paste the formula, it appears that I must click each cell and Cntl+Alt+Enter to make it an array? Since I have a lot of rows is there a quicker way?
- Patrick SilverwiseFeb 09, 2018Copper Contributor
Detlef,
Thanks for the quick response. Here is how I used your suggestion:
=IF(D2="","",OR(IFERROR(LEN(D2)-SEARCH({"Avenue";"Road"},D2)+1={6;4},FALSE)))
Here are the results. It can't seem to find Road. Thoughts?
Address1 Detlef Desired 123 Avenue TRUE TRUE 123 Road FALSE TRUE 123 Avenue Rd FALSE FALSE 123 Road Ave FALSE FALSE 123 Avenue Road FALSE TRUE 123 Road Avenue TRUE TRUE - Willy LauFeb 09, 2018Iron Contributor
Detlef Lewin's solution is an array formula. After you type the formula, press Ctrl + Shift + Enter. It works perfectly.
If you do not want to use array formula, then, try
=IF(LEN($D2)=0,"",OR(RIGHT($D2, LEN({" Avenue"," Road"}))={" Avenue"," Road"}))
- Patrick SilverwiseFeb 09, 2018Copper Contributor
My sincere apologies to Detlef Lewin. I'm a newbie with Excel and didn't realize I needed to use the Ctrl + Shift + Enter for his formula to work. My bad. Please forgive me.
Thanks for the heads up Willy Lau, and the non-array format to use with the IF statement.
Patrick
- Willy LauFeb 09, 2018Iron Contributor
Thanks, Detlef Lewin. I learn something new.
Then, I tried
=OR(RIGHT($D2,LEN({" Avenue"," Road"}))={" Avenue"," Road"})
This works too. This is not an array formula. However, if I want to make the search with dynamic keywords in cells, I still need to make it an array formula.
- Detlef_LewinFeb 09, 2018Silver Contributor
Willy, that's even better because CSE is not required. And it uses less functions and less operations.
- Patrick SilverwiseFeb 09, 2018Copper Contributor
Willy Lau,
Thanks for the quick response. This is how I used your formula:
=IF(D2="","",OR(RIGHT($D2,LEN({" Avenue"," Road"}))={" Avenue"," Road"}))
The result was what I was looking for:
Address1 Willy Desired 123 Avenue TRUE TRUE 123 Road TRUE TRUE 123 Avenue Rd FALSE FALSE 123 Road Ave FALSE FALSE 123 Avenue Road TRUE TRUE 123 Road Avenue TRUE TRUE Your mention of an array was insightful. I actually have 200 different street names to identify (and eventually abbreviate), e,g Circle, Trail, etc. The first step was to isolate the offenders. :)
What are your thoughts on what an array formula would look like?
Thanking you in advance. Patrick