Index, Match, Match to include a range and multiple tables

jeffdlinn

New Member
Joined
Nov 18, 2013
Messages
29
Office Version
  1. 365
Platform
  1. Windows
With the help of this forum I now have a index. match, match formula I need to expand upon. Based on the input in cell B2 I need the formula to select a value based on the range in Columns A and B. Additionally, the input in cell B1 will direct the formula to appropriate table (in this case Complete or Modified).

To clarify in this example if cell B1 was Modified (or another table reference), cell B2 was 23 the value in cell B4 would be 281.

Any ideas?


Book1
ABCDE
1Type:Complete
2Range:5
3Area:East
4Result:136
5
6Complete
7Range FromRange ToNorthEastWest
815104136140
9610104156161
101115120177181
111620137211216
122125152246251
132630155250254
143135186286291
153640186299303
164145215317321
174650215337342
18
19Modified
20Range FromRange ToNorthEastWest
2115114147152
22610115179183
231115144200204
241620160234238
252125175281285
262630178284289
273135221321325
283640221333337
294145250362367
304650250383388
Sheet1
Cell Formulas
RangeFormula
B4=INDEX(C8:E17,MATCH(B2,B8:B17),MATCH(B3,C7:E7))
 

Excel Facts

Back into an answer in Excel
Use Data, What-If Analysis, Goal Seek to find the correct input cell value to reach a desired result
Maybe this...

Create named ranges
Complete ---> A7:E17
Modified ---> A20:E30

Then try in B4
=INDEX(INDIRECT(B1),MATCH(B2,INDEX(INDIRECT(B1),0,1)),MATCH(B3,INDEX(INDIRECT(B1),1,0),0))

Hope this helps

M.
 
Last edited:
Upvote 0
Late to the party, but that was the way I went, too (named ranges)...
=INDEX(INDIRECT($B$1),MATCH(B2,B8:B17),MATCH(B3,C7:E7))
 
Upvote 0
Another option...
=INDEX((C8:E17,C21:D30),MATCH(B2,B8:B17),MATCH(B3,C7:E7),MATCH(B1,{"complete","modified"},0))
 
Upvote 0
Late to the party, but that was the way I went, too (named ranges)...
=INDEX(INDIRECT($B$1),MATCH(B2,B8:B17),MATCH(B3,C7:E7))


Hi Ford

If in all tables the values in columns 'Range From' and 'Range To' are identical and the regions are the same your simpler formula should work.
Like it.

M.
 
Upvote 0
Hi Ford

If in all tables the values in columns 'Range From' and 'Range To' are identical and the regions are the same your simpler formula should work.
Like it.

M.

Thanks :) I based it on the sample provided, which showed the same format. Perhaps another option - IF the tables are all identical - would be to have them side-by-side, then just use...
A​
B​
C​
D​
E​
F​
G​
H​
6​
Complete
Modified
7​
Range FromRange ToNorthEastWestNorthEastWest
8​
1​
5​
104​
136​
140​
114​
147​
152​
9​
6​
10​
104​
156​
161​
115​
179​
183​
10​
11​
15​
120​
177​
181​
144​
200​
204​
11​
16​
20​
137​
211​
216​
160​
234​
238​
12​
21​
25​
152​
246​
251​
175​
281​
285​
13​
26​
30​
155​
250​
254​
178​
284​
289​
14​
31​
35​
186​
286​
291​
221​
321​
325​
15​
36​
40​
186​
299​
303​
221​
333​
337​
16​
41​
45​
215​
317​
321​
250​
362​
367​
17​
46​
50​
215​
337​
342​
250​
383​
388​
=INDEX(C8:H17,MATCH(B2,B8:B17),MATCH(B3,C7:E7)+MATCH(B1,C6:H6,0)-1)
 
Upvote 0

Forum statistics

Threads
1,215,360
Messages
6,124,492
Members
449,166
Latest member
hokjock

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