May 12 2017
03:14 PM
- last edited on
Jul 25 2018
09:36 AM
by
TechCommunityAP
May 12 2017
03:14 PM
- last edited on
Jul 25 2018
09:36 AM
by
TechCommunityAP
I'm trying to extract a bunch of specific text combinations from cells and present it in a new cell.
This formula seems to work for two variables but I can't add any more variables too it.
=IFERROR(IF(SEARCH("*Sales*",B3,1),"Sales"),IF(SEARCH("*Arch*",B3,1),"Architecture"))
The text I would be searching for would be:
Sales,
Arch,
Land,
ALL,
Contracts,
Construction
and possibly a couple more.
Is there a way to do this?
May 12 2017 10:12 PM
Ah, a classic one.
Key words in column F, returned text in column G, text to check in A1.
=LOOKUP(PI(),1/COUNTIF(A1,"*"&$F$1:$F$6&"*"),$G$1:$G$6)
May 13 2017 12:04 PM
Dear Reuben Helder,
You may also use the below formula for the task. I have retained the same cell references that have been used by Detlef Lewin in the solution that he has provided.
=INDEX($F$1:$F$6,SUM(COUNTIF($A1,"*"&$F$1:$F$6&"*")*ROW(F1:F6)))
The formula given by Detlef Lewin can be amended, so that Pi() and column G will not be required.
=LOOKUP(1,1/COUNTIF($A1,"*"&$F$1:$F$6&"*"),$F$1:$F$6)
Vijaykumar Shetye
Spreadsheet Excellence,
Panaji, Goa, India
May 13 2017 12:16 PM
Dear Reuben Helder,
Kindly note that the below formula which I had given in the provious post, is an array formula.
=INDEX($F$1:$F$6,SUM(COUNTIF($A1,"*"&$F$1:$F$6&"*")*ROW($F$1:$F$6)))
Array formulas are entered using Control+Shift+Enter instead of Enter.
Vijaykumar Shetye
Spreadsheet Excellence,
Panaji, Goa, India
May 13 2017 01:09 PM
Vijaykumar Shetye, my formula does not need amending.
And your change from PI() to 1 will possibly give wrong results.
May 13 2017 10:37 PM
Dear Detlef Lewin,
Thanks for the reply and the correction. What is the significance of using Pi() in the formula?
Viaykumar Shetye,
Spreadsheet Excellence,
Panaji, Goa, India
May 14 2017 12:47 AM
PI() itself is just a little gag. The lookup value has to be a number greater than 1. So 1.1 would be enough or 2 if you prefer whole numbers.
May 14 2017 04:54 AM
Hi Reuben Helder,
Good day,
Please refer below formula to add more variable.
If statment is false then I have considered criteria is "NO MATCH"
IF(B3="MECH","MECHANICAL",IF(B3="ARCH","ARCHITECTURE",IF(B3="SALES","SALES",IF(B3="ELE","ELECTRICAL","NO MATCH"))))
Is this helful for you? please revert bach.
Thanks & regards,
Manoj P.
May 14 2017 05:10 AM
Hi Manoj,
It's worth to re-read task requirements and previous posts, your formula is about something different.
May 14 2017 09:31 AM
Dear Manoj Patgar,
(1) The problem has been posted on the forum by Reuben Helder because the formula using nested If functions is not adequate, due to its limitations.
The number of items in the text list is large (Sales, Arch, Land, ALL, Contracts, Construction and possibly a couple more), which nested IFs cannot handle. So the same formula with minor changes cannot work. The formula to be used has to be disigned to handle a long list of data.
(2) The data which is being searched is not MECH or ARCH. It will be like Searching MECH or ARCH within a data list that contain entries like 'ABC MECHANICAL ENGINEERS' or 'XYX ARCHITECTS'. Hence the wild card character (*) has been used.
Is it clear now?
Vijaykumar Shetye,
Spreadsheet Excellence,
Panaji, Goa India
May 14 2017 11:57 AM
SolutionI'm sorry but i see no limitations which could prevent to use nested IF. The only point it is a bit less flexible compare to nested If equivalents.
But what to use depends on goals, in some cases quick hardcording works quite fine.
If use formatting nested if becomes much more clear and editable. Like this
=IF(ISNUMBER(SEARCH("Sales", B3,1)),"Sales",
IF(ISNUMBER(SEARCH("Arch", B3,1)),"Architecture",
IF(ISNUMBER(SEARCH("Land", B3,1)),"Land",
IF(ISNUMBER(SEARCH("All", B3,1)),"All",
IF(ISNUMBER(SEARCH("Contracts", B3,1)),"Contracts",
IF(ISNUMBER(SEARCH("Construction", B3,1)),"Construction",
"No Match"
))))))
If instead of hardcoded strings use references nested IF becomes more flexible. And if add some extra references (nested if) for future strings to find it becomes even more flexible.
=IF(ISNUMBER(SEARCH($F$1,B3,1)),$G$1, IF(ISNUMBER(SEARCH($F$2,B3,1)),$G$2, IF(ISNUMBER(SEARCH($F$3,B3,1)),$G$3, IF(ISNUMBER(SEARCH($F$4,B3,1)),$G$4, IF(ISNUMBER(SEARCH($F$5,B3,1)),$G$5, IF(ISNUMBER(SEARCH($F$6,B3,1)),$G$6, IF(ISNUMBER(SEARCH($F$7,B3,1)),$G$7, IF(ISNUMBER(SEARCH($F$8,B3,1)),$G$8, IF(ISNUMBER(SEARCH($F$9,B3,1)),$G$9, "No Match" )))))))))
I don't vote for nested IF, i would like to say where is no limitations here. What to use that's concrete person choice.
May 16 2017 08:04 AM - edited May 16 2017 08:21 AM
Dear Mr. Sergi,
Yes. You are absolutely right.
<it is worth to re-read the question>
I am a beginner in excel and I am always welcome one who gives valuable suggestion.
With best regards,
Manoj.
May 16 2017 08:11 AM
Dear Mr. Vijaykumar,
Thank you and appreciate your support.
I am beginner and I am always welcome one who want to give valuable suggestions.
Thanks with best regards,
Manoj.
Apr 11 2019 12:48 PM
Hi I'm looking to create a formula to calculate how much I spend on groceries a year. For an example:
=IF(B1="nofrills","Loblaws","sobeys"
then display C1 (the $$)
otherwise false
Apr 12 2019 02:00 AM
@scmallory , that's a separate question, better to start new conversation with it from here.
Formula could be
=IF(SUM(--(B1={"nofrills","Loblaws","sobeys"})),C1)
Apr 12 2019 05:53 AM
@SergeiBaklanI'm having troubles posting in a new thread.
I tested out the formula and I was hoping cells in column D it would spit out the value in column C for anywhere it says "Food Basic" in column B. So the attached Test document.
Thank you,
Apr 12 2019 07:33 AM
@scmallory , to start new conversation go to the General Discussion as in my link and click
Formula doesn't work since in column B you have "food basics ", and you compare with "food basics". Due to space texts are different. Trim the cell like
=IF(SUM(--(TRIM(B1)={"nofrills","food basics","Loblaws","sobeys"})),C1)
Apr 12 2019 08:40 AM
@SergeiBaklanThanks it worked!
Apr 12 2019 08:47 AM
@scmallory , good, thank you for the confirmation
May 21 2019 12:01 PM
May 14 2017 11:57 AM
SolutionI'm sorry but i see no limitations which could prevent to use nested IF. The only point it is a bit less flexible compare to nested If equivalents.
But what to use depends on goals, in some cases quick hardcording works quite fine.
If use formatting nested if becomes much more clear and editable. Like this
=IF(ISNUMBER(SEARCH("Sales", B3,1)),"Sales",
IF(ISNUMBER(SEARCH("Arch", B3,1)),"Architecture",
IF(ISNUMBER(SEARCH("Land", B3,1)),"Land",
IF(ISNUMBER(SEARCH("All", B3,1)),"All",
IF(ISNUMBER(SEARCH("Contracts", B3,1)),"Contracts",
IF(ISNUMBER(SEARCH("Construction", B3,1)),"Construction",
"No Match"
))))))
If instead of hardcoded strings use references nested IF becomes more flexible. And if add some extra references (nested if) for future strings to find it becomes even more flexible.
=IF(ISNUMBER(SEARCH($F$1,B3,1)),$G$1, IF(ISNUMBER(SEARCH($F$2,B3,1)),$G$2, IF(ISNUMBER(SEARCH($F$3,B3,1)),$G$3, IF(ISNUMBER(SEARCH($F$4,B3,1)),$G$4, IF(ISNUMBER(SEARCH($F$5,B3,1)),$G$5, IF(ISNUMBER(SEARCH($F$6,B3,1)),$G$6, IF(ISNUMBER(SEARCH($F$7,B3,1)),$G$7, IF(ISNUMBER(SEARCH($F$8,B3,1)),$G$8, IF(ISNUMBER(SEARCH($F$9,B3,1)),$G$9, "No Match" )))))))))
I don't vote for nested IF, i would like to say where is no limitations here. What to use that's concrete person choice.