Index Match - Does Contents of a cell in a range match 1 particular cell and what is the match

MixedUpExcel

Board Regular
Joined
Apr 7, 2015
Messages
222
Office Version
  1. 365
Platform
  1. Windows
Hi All,

I couldn't find a specific match to this query but I'm assuming it's been asked before - please help or point me to the correct solution :)

Thanks.

Example:
Sheet 1 Cell A1 - Text (basically it a description of a product)

Sheet 1 Cell B1 - I will place my formula (this will then be dragged down to approx. Cell B1000 (where ever there is a description in Column A)

Sheet 2 Cells A1 to A5 (this Range can get bigger) contains the Range names of the products

[TABLE="class: grid, width: 500"]
<tbody>[TR]
[TD]Sheet1 Cell A1 (downwards)[/TD]
[TD]Sheet1 Cell B1[/TD]
[/TR]
[TR]
[TD]THIS IS THE SIMON ONE RANGE[/TD]
[TD]FORMULA HERE - SHOULD SHOW THE RESULT AS "SIMON" (without the quotes)[/TD]
[/TR]
[TR]
[TD]Next Row: PETER THE GREAT RANGE[/TD]
[TD]Next Row: Formula from Cell A2 dragged down and giving a result of "PETER" (without the quotes[/TD]
[/TR]
</tbody>[/TABLE]


Sheet2

[TABLE="class: outer_border, width: 500"]
<tbody>[TR]
[TD]Sheet2 Cell A1 (downwards)[/TD]
[TD][/TD]
[/TR]
[TR]
[TD]PAUL
[/TD]
[TD][/TD]
[/TR]
[TR]
[TD]JAMES[/TD]
[TD][/TD]
[/TR]
[TR]
[TD]PETER[/TD]
[TD][/TD]
[/TR]
[TR]
[TD]SIMON[/TD]
[TD][/TD]
[/TR]
[TR]
[TD]MIKE[/TD]
[TD][/TD]
[/TR]
</tbody>[/TABLE]

So recap: I want to put a formula in Cell B1 on Sheet1.. this will check the description in Cell A1 to see if there is a match (the Range Name eg. SIMON appears at some point in that description in Cell A1)

IF there is a match, it will then put the name of the Range it has found in the description.

IF there is no match, then it will either put 'no match' or blank eg. "" or anything else.

I can't quite get my head around what Index Match Vlookup IF etc that I need to use to construct..

Thanks in advance.

Simon
 

Excel Facts

Create a Pivot Table on a Map
If your data has zip codes, postal codes, or city names, select the data and use Insert, 3D Map. (Found to right of chart icons).
In B1 of Sheet1 enter and copy down:

=LOOKUP(9.99999999999999E+307,SEARCH(" "&Sheet2!$A$1:$A$5&" "," "&$A1&" "),Sheet2!$A$1:$A$5)
 
Last edited:
Upvote 0
In B1 of Sheet1 enter and copy down:

=LOOKUP(9.99999999999999E+307,SEARCH(" "&Sheet2!$A$1:$A$5&" "," "&$A1&" "),Sheet2!$A$1:$A$5)

Hi Aladin,

That appears to work perfectly.. thank you so much for getting back to me so quickly with that solution.

I can probably work out most of it but what does the "9.99999999999999E+307" do?

Thanks.
 
Upvote 0
LOOKUP attempting to find this big number in a reference it is given lands on the last number in that reference.
Thus, SEARCH delivers a reference with numbers and/or #VALUE ! errors while searching a set of values in A1
from which LOOKUP picks out the last one if any and correlates the position of that last number with an entry in Sheet2!$A$1:$A$5.

See for more:
https://www.mrexcel.com/forum/excel-questions/102091-9-9999999-a.html
https://www.mrexcel.com/forum/excel-questions/724843-there-case-sensitive-vlookup.html
 
Upvote 0

Forum statistics

Threads
1,223,098
Messages
6,170,100
Members
452,301
Latest member
QualityAssurance

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