Excel Formula - if cell contain information from column

Johns90

New Member
Joined
Feb 3, 2021
Messages
12
Office Version
  1. 365
Platform
  1. Windows
Hello,

i am looking an Excel fomula :

In one Sheet i have exported the data from a tool with inside the colmun A information and client name
In the other sheet i have in column B the list of clients (clean list)

Please see the example :

Sheet1, column A :

End User: Coupland Cardiff contract 2245503
End User: Sanofi contract 14785258
End User: South Yorkshire contract 2257458
etc,

Sheet2, column B :
Coupland Cardiff
Sanofi
South Yorkshire
etc,

Today i am using this formula in order to extract the only the client name from Sheet1 column A if it's found in Sheet2 column B :
In B2 from Sheet1 =IFERROR(LOOKUP(PI(),1/COUNTIF(A2,"*"&'Sheet2B2:B4&"*"),'Sheet2B2:B4),"")
It's working but the formula is not working if i add a new client name in sheet2 column B.
I am trying to find something dymanique, like not take the list (Sheet2B2:B4) but all the column (sheet2B:B) in order to find in my sheet1 when i add also a new client name

Thanks a lot for your help
 

Excel Facts

Round to nearest half hour?
Use =MROUND(A2,"0:30") to round to nearest half hour. Use =CEILING(A2,"0:30") to round to next half hour.
How about
Excel Formula:
=FILTER(Sheet2!$B$2:$B$11,(Sheet2!$B$2:$B$11<>"")*(ISNUMBER(SEARCH(Sheet2!$B$2:$B$11,A2))),"")
or
Excel Formula:
=IFERROR(LOOKUP(2,1/(COUNTIF(A2,"*"&Sheet2!$B$2:$B$40&"*")>0)/(Sheet2!$B$2:$B$40<>""),Sheet2!$B$2:$B$40),"")
 
Upvote 0
How about
Excel Formula:
=FILTER(Sheet2!$B$2:$B$11,(Sheet2!$B$2:$B$11<>"")*(ISNUMBER(SEARCH(Sheet2!$B$2:$B$11,A2))),"")
or
Excel Formula:
=IFERROR(LOOKUP(2,1/(COUNTIF(A2,"*"&Sheet2!$B$2:$B$40&"*")>0)/(Sheet2!$B$2:$B$40<>""),Sheet2!$B$2:$B$40),"")
It's working, thanks a lot.
Another question, it's working perfectly with text iam wondering do you have the same thing if we are looking numbers or dates ?
Thanks
 
Upvote 0
They both work with numbers
+Fluff 1.xlsm
ABCDEF
1
2End User: Coupland Cardiff contract 2245503224550322455032257458
3End User: Sanofi contract 1478525814785258147852582245503
4End User: South Yorkshire contract 22574582257458225745814785258
5
Master
Cell Formulas
RangeFormula
B2:B4B2=FILTER($F$2:$F$10,($F$2:$F$10<>"")*(ISNUMBER(SEARCH($F$2:$F$10,A2))))
C2:C4C2=IFERROR(LOOKUP(2,1/(COUNTIF(A2,"*"&$F$2:$F$10&"*")>0)/($F$2:$F$10<>""),$F$2:$F$10),"")
 
Upvote 0

Forum statistics

Threads
1,213,543
Messages
6,114,236
Members
448,555
Latest member
RobertJones1986

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