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.