Formula to match partial text string

stroffso

Board Regular
Joined
Jul 12, 2016
Messages
160
Office Version
  1. 365
Platform
  1. Windows
Hi,

I have looked at various threads on this forum and nothing appears to get the solution requried.

I have the following formula but I want to adapt it so that I can return row numbers where there is just a partial match of cell M4. At present it matches everthing exactly as it is in cell M4.

=IFERROR(SMALL(IF($A$1:$K$1000=M4,ROW($A$1:$K$1000)-MIN(ROW($A$1:$K$1000))+1),1),"")

Have tried this
=IFERROR(SMALL(IF($A$1:$K$1000="*"&M4&"*",ROW($A$1:$K$1000)-MIN(ROW($A$1:$K$1000))+1),1),"")

However it doesnt seem to work. Any suggestions greatly welcome

thanks
 

Excel Facts

Did you know Excel offers Filter by Selection?
Add the AutoFilter icon to the Quick Access Toolbar. Select a cell containing Apple, click AutoFilter, and you will get all rows with Apple
You could try searching for the value...

=IFERROR(SMALL(IF(ISNUMBER(SEARCH(M4, $A$1:$K$1000)), ROW($A$1:$K$1000)-MIN(ROW($A$1:$K$1000))+1), 1), "")
 
Upvote 0
In M5 control+shift+enter, not just enter, and copy down:

1.

=IFERROR(SMALL(IF(MMULT(ISNUMBER(SEARCH($M$4,$A$1:$K$1000))+0,TRANSPOSE(COLUMN($A$1:$K$1000)^0)),ROW($A$1:$K$1000)-ROW($A$1)+1),ROWS($M$5:M5)),"")

2. Same as the one you tried and mrhstn modifies, less the additional MIN call.

=IFERROR(SMALL(IF(ISNUMBER(SEARCH($M$4,$A$1:$K$1000)),ROW($A$1:$K$1000)-ROW($A$1)+1),ROWS($M$5:M5)),"")

Note A. Both [1] and [2] give you relative row numbers of the records in which M4 wholly or partially occurs; [1] skips duplicate occurrences in the same record.
Note B. If Excel-native row numbers are required, replace ROW($A$1:$K$1000)-ROW($A$1)+1 with ROW($A$1:$K$1000).
 
Upvote 0
Thanks so much that worked perfectly

You could try searching for the value...

=IFERROR(SMALL(IF(ISNUMBER(SEARCH(M4, $A$1:$K$1000)), ROW($A$1:$K$1000)-MIN(ROW($A$1:$K$1000))+1), 1), "")
 
Upvote 0
Wow, this is excellent, could you explain a little what the first formula is doing in the sense of the Mmulti and transpose functions?

In M5 control+shift+enter, not just enter, and copy down:

1.

=IFERROR(SMALL(IF(MMULT(ISNUMBER(SEARCH($M$4,$A$1:$K$1000))+0,TRANSPOSE(COLUMN($A$1:$K$1000)^0)),ROW($A$1:$K$1000)-ROW($A$1)+1),ROWS($M$5:M5)),"")

2. Same as the one you tried and mrhstn modifies, less the additional MIN call.

=IFERROR(SMALL(IF(ISNUMBER(SEARCH($M$4,$A$1:$K$1000)),ROW($A$1:$K$1000)-ROW($A$1)+1),ROWS($M$5:M5)),"")

Note A. Both [1] and [2] give you relative row numbers of the records in which M4 wholly or partially occurs; [1] skips duplicate occurrences in the same record.
Note B. If Excel-native row numbers are required, replace ROW($A$1:$K$1000)-ROW($A$1)+1 with ROW($A$1:$K$1000).
 
Upvote 0
Let's just have A1:K15 of which except the subarea below contains no data...

[TABLE="class: cms_table_grid"]
<tbody>[TR]
[TD]Row\Col[/TD]
[TD]
A​
[/TD]
[TD]
B​
[/TD]
[TD]
C​
[/TD]
[TD]
D​
[/TD]
[TD]
E​
[/TD]
[/TR]
[TR]
[TD]
1​
[/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD]jad[/TD]
[/TR]
[TR]
[TD]
2​
[/TD]
[TD]jad[/TD]
[TD][/TD]
[TD]jad[/TD]
[TD][/TD]
[TD][/TD]
[/TR]
[TR]
[TD]
3​
[/TD]
[TD][/TD]
[TD][/TD]
[TD]najad[/TD]
[TD][/TD]
[TD][/TD]
[/TR]
[TR]
[TD]
4​
[/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[/TR]
[TR]
[TD]
5​
[/TD]
[TD]jad[/TD]
[TD][/TD]
[TD]jad[/TD]
[TD][/TD]
[TD][/TD]
[/TR]
[TR]
[TD]
6​
[/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD]x[/TD]
[TD][/TD]
[/TR]
</tbody>[/TABLE]



Let M4 house the string jad.

The formula

=IFERROR(SMALL(IF(MMULT(ISNUMBER(SEARCH($M$4,$A$1:$K$15))+0,TRANSPOSE(COLUMN($A$1:$K$15)^0)),ROW($A$1:$K$15)-ROW($A$1)+1),ROWS($M$5:M5)),"")

yields the following output in M5 and downwards:

[TABLE="class: cms_table_grid"]
<tbody>[TR]
[TD]Row\Col[/TD]
[TD]
M
[/TD]
[/TR]
[TR]
[TD]
4
[/TD]
[TD]jad[/TD]
[/TR]
[TR]
[TD]
5
[/TD]
[TD]
1
[/TD]
[/TR]
[TR]
[TD]
6
[/TD]
[TD]
2
[/TD]
[/TR]
[TR]
[TD]
7
[/TD]
[TD]
3
[/TD]
[/TR]
[TR]
[TD]
8
[/TD]
[TD]
5
[/TD]
[/TR]
</tbody>[/TABLE]



according to the following steps...

=IFERROR(SMALL(IF(MMULT({0,0,0,0,1,0,0,0,0,0,0;1,0,1,0,0,0,0,0,0,0,0;0,0,1,0,0,0,0,0,0,0,0;0,0,0,0,0,0,0,0,0,0,0;1,0,1,0 ,0,0,0,0,0,0,0;0,0,0,0,0,0,0,0,0,0,0;0,0,0,0,0,0,0,0,0,0,0;0,0,0,0,0,0,0,0,0,0,0;0,0,0,0,0,0,0,0,0,0,0;0,0,0,0,0,0,0,0,0 ,0,0;0,0,0,0,0,0,0,0,0,0,0;0,0,0,0,0,0,0,0,0,0,0;0,0,0,0,0,0,0,0,0,0,0;0,0,0,0,0,0,0,0,0,0,0;0,0,0,0,0,0,0,0,0,0,0},TRAN SPOSE(COLUMN($A$1:$K$15)^0)),ROW($A$1:$K$15)-ROW($A$1)+1),ROWS($L$5:L5)),"")

=IFERROR(SMALL(IF(MMULT({0,0,0,0,1,0,0,0,0,0,0;1,0,1,0,0,0,0,0,0,0,0;0,0,1,0,0,0,0,0,0,0,0;0,0,0,0,0,0,0,0,0,0,0;1,0,1,0 ,0,0,0,0,0,0,0;0,0,0,0,0,0,0,0,0,0,0;0,0,0,0,0,0,0,0,0,0,0;0,0,0,0,0,0,0,0,0,0,0;0,0,0,0,0,0,0,0,0,0,0;0,0,0,0,0,0,0,0,0 ,0,0;0,0,0,0,0,0,0,0,0,0,0;0,0,0,0,0,0,0,0,0,0,0;0,0,0,0,0,0,0,0,0,0,0;0,0,0,0,0,0,0,0,0,0,0;0,0,0,0,0,0,0,0,0,0,0},{1;1 ;1;1;1;1;1;1;1;1;1}),ROW($A$1:$K$15)-ROW($A$1)+1),ROWS($L$5:L5)),"")

=IFERROR(SMALL(IF({1;2;1;0;2;0;0;0;0;0;0;0;0;0;0},ROW($A$1:$K$15)-ROW($A$1)+1),ROWS($L$5:L5)),"")

MMULT multiplies the matrix obtained with the SERACH bit with a vector.

=IFERROR(SMALL({1;2;3;FALSE;5;FALSE;FALSE;FALSE;FALSE;FALSE;FALSE;FALSE;FALSE;FALSE;FALSE},ROWS($L$5:L5)),"")

=IFERROR(SMALL({1;2;3;FALSE;5;FALSE;FALSE;FALSE;FALSE;FALSE;FALSE;FALSE;FALSE;FALSE;FALSE},1),"")

=IFERROR(1,"")

1

And so on.

Try the description of MMULT on Excel's help pages for more info.

 
Last edited:
Upvote 0
That is brilliant thank you so much

Let's just have A1:K15 of which except the subarea below contains no data...

[TABLE="class: cms_table_grid"]
<tbody>[TR]
[TD]Row\Col[/TD]
[TD]
A​
[/TD]
[TD]
B​
[/TD]
[TD]
C​
[/TD]
[TD]
D​
[/TD]
[TD]
E​
[/TD]
[/TR]
[TR]
[TD]
1​
[/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD]jad[/TD]
[/TR]
[TR]
[TD]
2​
[/TD]
[TD]jad[/TD]
[TD][/TD]
[TD]jad[/TD]
[TD][/TD]
[TD][/TD]
[/TR]
[TR]
[TD]
3​
[/TD]
[TD][/TD]
[TD][/TD]
[TD]najad[/TD]
[TD][/TD]
[TD][/TD]
[/TR]
[TR]
[TD]
4​
[/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[/TR]
[TR]
[TD]
5​
[/TD]
[TD]jad[/TD]
[TD][/TD]
[TD]jad[/TD]
[TD][/TD]
[TD][/TD]
[/TR]
[TR]
[TD]
6​
[/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD]x[/TD]
[TD][/TD]
[/TR]
</tbody>[/TABLE]



Let M4 house the string jad.

The formula

=IFERROR(SMALL(IF(MMULT(ISNUMBER(SEARCH($M$4,$A$1:$K$15))+0,TRANSPOSE(COLUMN($A$1:$K$15)^0)),ROW($A$1:$K$15)-ROW($A$1)+1),ROWS($M$5:M5)),"")

yields the following output in M5 and downwards:

[TABLE="class: cms_table_grid"]
<tbody>[TR]
[TD]Row\Col[/TD]
[TD]
M
[/TD]
[/TR]
[TR]
[TD]
4
[/TD]
[TD]jad[/TD]
[/TR]
[TR]
[TD]
5
[/TD]
[TD]
1
[/TD]
[/TR]
[TR]
[TD]
6
[/TD]
[TD]
2
[/TD]
[/TR]
[TR]
[TD]
7
[/TD]
[TD]
3
[/TD]
[/TR]
[TR]
[TD]
8
[/TD]
[TD]
5
[/TD]
[/TR]
</tbody>[/TABLE]



according to the following steps...

=IFERROR(SMALL(IF(MMULT({0,0,0,0,1,0,0,0,0,0,0;1,0,1,0,0,0,0,0,0,0,0;0,0,1,0,0,0,0,0,0,0,0;0,0,0,0,0,0,0,0,0,0,0;1,0,1,0 ,0,0,0,0,0,0,0;0,0,0,0,0,0,0,0,0,0,0;0,0,0,0,0,0,0,0,0,0,0;0,0,0,0,0,0,0,0,0,0,0;0,0,0,0,0,0,0,0,0,0,0;0,0,0,0,0,0,0,0,0 ,0,0;0,0,0,0,0,0,0,0,0,0,0;0,0,0,0,0,0,0,0,0,0,0;0,0,0,0,0,0,0,0,0,0,0;0,0,0,0,0,0,0,0,0,0,0;0,0,0,0,0,0,0,0,0,0,0},TRAN SPOSE(COLUMN($A$1:$K$15)^0)),ROW($A$1:$K$15)-ROW($A$1)+1),ROWS($L$5:L5)),"")

=IFERROR(SMALL(IF(MMULT({0,0,0,0,1,0,0,0,0,0,0;1,0,1,0,0,0,0,0,0,0,0;0,0,1,0,0,0,0,0,0,0,0;0,0,0,0,0,0,0,0,0,0,0;1,0,1,0 ,0,0,0,0,0,0,0;0,0,0,0,0,0,0,0,0,0,0;0,0,0,0,0,0,0,0,0,0,0;0,0,0,0,0,0,0,0,0,0,0;0,0,0,0,0,0,0,0,0,0,0;0,0,0,0,0,0,0,0,0 ,0,0;0,0,0,0,0,0,0,0,0,0,0;0,0,0,0,0,0,0,0,0,0,0;0,0,0,0,0,0,0,0,0,0,0;0,0,0,0,0,0,0,0,0,0,0;0,0,0,0,0,0,0,0,0,0,0},{1;1 ;1;1;1;1;1;1;1;1;1}),ROW($A$1:$K$15)-ROW($A$1)+1),ROWS($L$5:L5)),"")

=IFERROR(SMALL(IF({1;2;1;0;2;0;0;0;0;0;0;0;0;0;0},ROW($A$1:$K$15)-ROW($A$1)+1),ROWS($L$5:L5)),"")

MMULT multiplies the matrix obtained with the SERACH bit with a vector.

=IFERROR(SMALL({1;2;3;FALSE;5;FALSE;FALSE;FALSE;FALSE;FALSE;FALSE;FALSE;FALSE;FALSE;FALSE},ROWS($L$5:L5)),"")

=IFERROR(SMALL({1;2;3;FALSE;5;FALSE;FALSE;FALSE;FALSE;FALSE;FALSE;FALSE;FALSE;FALSE;FALSE},1),"")

=IFERROR(1,"")

1

And so on.

Try the description of MMULT on Excel's help pages for more info.

 
Upvote 0

Forum statistics

Threads
1,223,903
Messages
6,175,286
Members
452,631
Latest member
a_potato

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