Is isnumber search with index match possible?

Topkapi

New Member
Joined
May 30, 2023
Messages
3
Office Version
  1. 2007
Platform
  1. Windows
hello mrexcell crowd. i am trying to make a formula to index match based on two conditions however i cannot use index match
because the cells have to match exactly in the query i.e query 'g' searches for 'g', so i am trying to do a
combination of isnumber search and index match.

so in plain english it would be as follows:

if the letter 'g' is found in cell e10 then search b3 for g, if a match is found then
search row c2:h2 for data contained in F10: 1600

where

cell B3 contains data g
cell F10 contains 1600
cell e10 contains g4
cell G3 contains 14


the two search queries correspond at cell G3 to return the figure therein: 14

i would need to repeat the thread in the formula 3 times for G, S, and H like as follows:
IF(ISNUMBER(SEARCH("g",F70)),P70-$M$65,IF(ISNUMBER(SEARCH("s",F70)),P70-$M$66,IF(ISNUMBER(SEARCH("h",F70)),P70-$M$67)))

this is because cell e10 would have alternating information inputed on every use.i.e g4,s5,h8 etc and i only want to search for the letter not the exact text with the number.
and i would need to search and match a different row depending on which letter is inputted in e10.
way too convoluted for my basic abilities.
any ideas anyone?

while writing this i realised i don't even have to specify to search b3 for 'g' merely if 'g' is entered in e10 search row c3:h3, if 's' is in e10 search row c4:h4 and so on.

example - isnumber grid.jpg
 

Excel Facts

Format cells as time
Select range and press Ctrl+Shift+2 to format cells as time. (Shift 2 is the @ sign).
Book1
ABCDEFGH
1
2100013001400150016001800
3g101112131415
4s202122232425
5h303132333435
6
7
8
9conditiondist
10g4160014
11
Sheet1
Cell Formulas
RangeFormula
F10F10=SUMPRODUCT($C$3:$H$5,($C$2:$H$2=$E$10)*($B$3:$B$5=LEFT($D$10,1)))
 
Upvote 0
Hi, try this formula for G10 cell
=IFERROR(IF(AND(IFERROR(MATCH(LEFT(SUBSTITUTE(SUBSTITUTE(SUBSTITUTE(SUBSTITUTE(SUBSTITUTE(SUBSTITUTE(SUBSTITUTE(SUBSTITUTE(SUBSTITUTE(SUBSTITUTE(E10,"0",""),"1",""),"2",""),"3",""),"4",""),"5",""),"6",""),"7",""),"8",""),"9",""),1),B:B,0),0)>0,IFERROR(MATCH(F10,2:2,0),0)>0),INDIRECT(ADDRESS(IFERROR(MATCH(LEFT(SUBSTITUTE(SUBSTITUTE(SUBSTITUTE(SUBSTITUTE(SUBSTITUTE(SUBSTITUTE(SUBSTITUTE(SUBSTITUTE(SUBSTITUTE(SUBSTITUTE(E10,"0",""),"1",""),"2",""),"3",""),"4",""),"5",""),"6",""),"7",""),"8",""),"9",""),1),B:B,0),0),IFERROR(MATCH(F10,2:2,0),0))),""),"")

Search.xlsx

Search.png
 
Upvote 0
i am trying to make a formula to index match based on two conditions

i.e g4,s5,h8 etc and i only want to search for the letter
Welcome to the MrExcel board!

Would this INDEX/MATCH do what you were trying to do?

23 05 30.xlsm
ABCDEFGHI
1
2100013001400150016001800
3g101112131415
4s202122232425
5h303132333435
6
7
8
9conditiondist
10g4160014
11h3130031
INDEX MATCH
Cell Formulas
RangeFormula
F10:F11F10=INDEX(C$3:H$5,MATCH(LEFT(D10,1),B$3:B$5,0),MATCH(E10,C$2:H$2,0))
 
Upvote 0
Hi, I created a new table with a new parameter (on SearchNew worksheet in F column, F8...). The new parameter determines that which letter of the text works in the search.

The formulas used in the new table...
SearchOrig!G8: =IFERROR(IF(AND(IFERROR(MATCH(LEFT(SUBSTITUTE(SUBSTITUTE(SUBSTITUTE(SUBSTITUTE(SUBSTITUTE(SUBSTITUTE(SUBSTITUTE(SUBSTITUTE(SUBSTITUTE(SUBSTITUTE(E8,"0",""),"1",""),"2",""),"3",""),"4",""),"5",""),"6",""),"7",""),"8",""),"9",""),1),B:B,0),0)>0,IFERROR(MATCH(F8,$2:$2,0),0)>0),INDIRECT(ADDRESS(IFERROR(MATCH(LEFT(SUBSTITUTE(SUBSTITUTE(SUBSTITUTE(SUBSTITUTE(SUBSTITUTE(SUBSTITUTE(SUBSTITUTE(SUBSTITUTE(SUBSTITUTE(SUBSTITUTE(E8,"0",""),"1",""),"2",""),"3",""),"4",""),"5",""),"6",""),"7",""),"8",""),"9",""),1),B:B,0),0),IFERROR(MATCH(F8,$2:$2,0),0))),""),"") (Range: G8:G11 ...)
SearchNew!H8: =IFERROR(IF(AND(IFERROR(MATCH(MID(SUBSTITUTE(SUBSTITUTE(SUBSTITUTE(SUBSTITUTE(SUBSTITUTE(SUBSTITUTE(SUBSTITUTE(SUBSTITUTE(SUBSTITUTE(SUBSTITUTE(E8,"0",""),"1",""),"2",""),"3",""),"4",""),"5",""),"6",""),"7",""),"8",""),"9",""),F8,1),B:B,0),0)>0,IFERROR(MATCH(G8,$2:$2,0),0)>0),INDIRECT(ADDRESS(IFERROR(MATCH(MID(SUBSTITUTE(SUBSTITUTE(SUBSTITUTE(SUBSTITUTE(SUBSTITUTE(SUBSTITUTE(SUBSTITUTE(SUBSTITUTE(SUBSTITUTE(SUBSTITUTE(E8,"0",""),"1",""),"2",""),"3",""),"4",""),"5",""),"6",""),"7",""),"8",""),"9",""),F8,1),B:B,0),0),IFERROR(MATCH(G8,$2:$2,0),0))),""),"") (Range: H8:H23 ...)

SearchN.xlsx

SearchN1.png


SearchN2.png
 
Upvote 0
man, simplicity is king. i was so focused on going down the isnumber search rd road because i was using it for other things
i didn't think laterally about other solutions. Ironically i was using LEFT in another part of the workbook.

@kevin9999

worked perfectly

@Peter_SSs

worked perfectly

@fjns

worked but would need an adjustment with B:B and row2 to suit my purpose as i need to specify a limited range in both column b and row2 as there are multiple tables on the same sheet and different data metrics in the second row. Anyway big effort. i could never have come up with that if i lived to be a million.

second solution

just to point out, in the condition entry cell the parameters i specified g,s,h would never appear together at the same time i.e gs or hg.
it would be one or another. Also labour wise, specifying which figure to return; 1st, 2nd, 3rd, as an approach would add too much data entry labour which i want to remove.

In any case i needed the simple solutions as the tables these functions are for are already made and this would require substantial modification for this to work.The problem i have found with the real long equations is if an error is made i don't know how to find and correct it.

anyway Much appreciation for everyones' effort as i have been procrastinating on finishing this workbook because of the excessively long formulas i have had to concoct. So big thanks all

there are two more things that have arisen once i tested it. so i can make this more flexible:


INDEX(C$3:H$5,MATCH(LEFT(D10,1),B$3:B$5,0),MATCH(E10,C$2:H$2,0))


1) where do i insert the If_false argument if a figure in c2:h2 is not found and i need another cell to manually insert information
so in our example 1200 is not found so data in a1 is returned? I tried putting it a the '0' in (E10,C$2:H$2,0)) but #N/A is returned

2) how do you formulate the argument to match left in (c$3:h$)?
 
Upvote 0
1) where do i insert the If_false argument if a figure in c2:h2 is not found and i need another cell to manually insert information
so in our example 1200 is not found so data in a1 is returned?
Is this what you mean?

Topkapi.xlsm
ABCDEFGH
1xx
2100013001400150016001800
3g101112131415
4s202122232425
5h303132333435
6
7
8
9conditiondist
10g4160014
11h31200xx
INDEX MATCH
Cell Formulas
RangeFormula
F10:F11F10=IFNA(INDEX(C$3:H$5,MATCH(LEFT(D10,1),B$3:B$5,0),MATCH(E10,C$2:H$2,0)),A$1)


2) how do you formulate the argument to match left in (c$3:h$)?
I don't understand what you are asking here.
 
Upvote 0

the example in the picture would be exactly what i was looking for however i got #name? error in my test sheet.
I repeatedly tried with different sheets new work books but to no avail so I gave up on it. later it dawned on me to check when this formula was introduced to excel. this turned out to be the reason. i have excel 2007 and ISNA was introduced in excell 2013. as i found here:


Tried their solutions

=ISERROR(INDEX(C$3:H$5,MATCH(LEFT(D10,1),B$3:B$5,0),MATCH(E10,C$2:H$2,0)),A$1) -
get: you've entered to many arguments for this function

=ISNA(INDEX(C$3:H$5,MATCH(LEFT(D10,1),B$3:B$5,0),MATCH(E10,C$2:H$2,0)),A$1)
get: you've entered to many arguments for this function

=IF(ISNA(INDEX(C$3:H$5,MATCH(LEFT(D10,1),B$3:B$5,0),MATCH(E10,C$2:H$2,0)),A$1)
get: you've entered to many arguments for this function

i don't know where the other ')' bracket goes to close the added bracket for the added =ISERROR(INDEX
IF(ISNA ..... and =IF(ISNA(INDEX brackets.

that is actually the problem in all 3 formulas i attempted.

even if that were corrected not sure these would work.


2) Yes my bad - how do you formulate the argument to match left in (c$3:h$)?

total brain fade. match left in (c$3:h$) was supposed to be (b$3:b$5)

so if it was

GET
SAM
HAIL

'G', 'S' and 'H' would be searched for.

so the formula would represent something like match left - 1st letter - in cell d10 (g4) and find in b3:b5

but only match first letter i.e 'G" in the word GET. then search for the rest etc.
 
Upvote 0
it dawned on me to check when this formula was introduced to excel. this turned out to be the reason.
Ah, it didn't dawn on me either, sorry about that. :oops:
Try this one instead.

Topkapi.xlsm
ABCDEFGH
1xx
2100013001400150016001800
3g101112131415
4s202122232425
5h303132333435
6
7
8
9conditiondist
10g4160014
11h31200xx
INDEX MATCH
Cell Formulas
RangeFormula
F10:F11F10=IF(ISNA(INDEX(C$3:H$5,MATCH(LEFT(D10,1),B$3:B$5,0),MATCH(E10,C$2:H$2,0))),A$1,INDEX(C$3:H$5,MATCH(LEFT(D10,1),B$3:B$5,0),MATCH(E10,C$2:H$2,0)))
 
Upvote 0
Change IFNA to IFERROR:

=IFERROR(INDEX(C$3:H$5,MATCH(LEFT(D10,1),B$3:B$5,0),MATCH(E10,C$2:H$2,0)),A$1)
 
Upvote 0

Forum statistics

Threads
1,223,228
Messages
6,170,871
Members
452,363
Latest member
merico17

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