Index-match return value?

pjkaphlen

Board Regular
Joined
Aug 3, 2015
Messages
85
Office Version
  1. 365
  2. 2013
Platform
  1. Windows
Hello guys, can you help me with these? I have these two sheets and from the data on Sheet 1 I would like to return a value at sheet 1 taken from Sheet 2. Notice the Zone and Weight values on Sheet 1 which has an equivalent Cost for every Zone-Weight pair.

I have used Index-match in order to return the value. However I also used "CEILING" function of 0.5. Which was only applicable for data the increments of 0.5 and not applicable to all the weight on Sheet 2. Notice that some have increments of 2 and some larger weights have an increment of 5.

here is the formula that I am using. What do you think can I add in order for this program to return the correct value?

=INDEX(Sheet2!B2:G5,MATCH(CEILING(Sheet1!B1,0.5),Sheet2!A2:A5,0),MATCH(Sheet1!B2,Sheet2!B1:G1,0))

P.S: Any fraction of a kg over the weight on sheet 2 should take the next higher weight rate. This means the the 30kg should be the reference for the case of the Weight given on Sheet 1.

Sheet 1
Zone3
Weight25.1
Cost$---.--

<tbody>
</tbody>

Sheet 2
weight/zone123
9$1.5$2.5$3.5
9.5$4.5$5.5$6.5
10$7.5$8.5$9.5
11$10.5$11.5$11.6
12$14.5$14.8$15.0
13$16.1$16.3$16.5
14$17.4$17.8$18.0
16$18.2$18.4$18.9
18$19.0$19.5$19.8
20$20.1$20.5$21.0
25$22.5$22.9$23.5
30$25.2$25.6$25.8

<tbody>
</tbody>






















All replies shall be greatly appreciated! Thanks in advance guys!
 

Excel Facts

Who is Mr Spreadsheet?
Author John Walkenbach was Mr Spreadsheet until his retirement in June 2019.
See if this works.
This is an array formula and must be entered with CTRL-SHIFT-ENTER.
Change ranges to match your data.
Excel Workbook
AB
1Zone3
2Weight25.1
3Cost25.80
Sheet1


Excel Workbook
ABCDE
1weight/zone123
29$1.50$2.50$3.50
39.5$4.50$5.50$6.50
410$7.50$8.50$9.50
511$10.50$11.50$11.60
612$14.50$14.80$15.00
713$16.10$16.30$16.50
814$17.40$17.80$18.00
916$18.20$18.40$18.90
1018$19.00$19.50$19.80
1120$20.10$20.50$21.00
1225$22.50$22.90$23.50
1330$25.20$25.60$25.80
14
Sheet2



[/B]
 
Upvote 0
Thanks AhoyNC! I have tried the formula and it works. Some problem occurred though. When I entered Zone. it already outputs the value of the base weight. I think this is because of the ROW function. Please refer below.
-ROW(Sheet2!$A$2)


<tbody>
</tbody>
</td></tr></tbody></table>
 
Upvote 0
I don't understand what you mean by "When I entered Zone. it already outputs the value of the base weight".
Could you give an example of what you are entering and the wrong result, plus result you are expecting.
Also, did you change the ranges to match your data. From your formula in post one it looks like you have titles (maybe zones) from B1 to G1. My example only went out to D1.
 
Upvote 0
Another option,

Sheet1 B3, enter formula :

=LOOKUP(B2,Sheet2!A1:A13,OFFSET(Sheet2!A$2,,MATCH(B1,Sheet2!B1:D1),13))
 
Upvote 0
@Bosco_yip
Your formula seems to return the wrong answer if the weights are equal. Example: if zone 3 and weight 18 your formula returns $21 instead of $19.80.
 
Upvote 0
@Bosco_yip
Your formula seems to return the wrong answer if the weights are equal. Example: if zone 3 and weight 18 your formula returns $21 instead of $19.80.
Hi AhoyNC,

I noted my mistake, then disregard my posted formula.

Thanks your advice.

Bosco
 
Upvote 0
@AhoyNC. Sorry for that. Let me rephrase my sentence. The program returns the correct output. The problem though is, even if I haven't input any value at weight (weight = 0) and I tried to input a value for "Zone". Let's say, if Zone = 1 and Weight = "Blank"
the result for the "Price" should also be blank, right? But since the formula uses MIN and ROW function, then it will always output a value even if I leave the "Weight" cell blank.

the output would always be taken from Row(2) of sheet2
 
Upvote 0
@Bosco_yip
Your formula seems to return the wrong answer if the weights are equal. Example: if zone 3 and weight 18 your formula returns $21 instead of $19.80.

Hi AhoyNC,

The non-array formula is fixed herein :

=IF(COUNT(B1:B2)>1,LOOKUP(ROW(A1),COUNTIF(OFFSET(Sheet2!$A$1,,,ROW($1:$13)),">="&B2)+1,OFFSET(Sheet2!A$2,,MATCH(B1,Sheet2!$B$1:$D$1),13)),"")

Regards
 
Upvote 0
OK.
You could change my formula to:
Code:
=IF(OR($B$1="",$B$2=""),"",INDEX(Sheet2!$B$2:$D$13,MIN(IF(Sheet2!$A$2:$A$13>=Sheet1!$B$2,ROW(Sheet2!$A$2:$A$13)-ROW(Sheet2!$A$2)+1)),MATCH($B$1,Sheet2!$B$1:$D$1,0)))
It is an array formula and must be entered with CTRL-SHIFT-ENTER.

The formula from bosco_yip should also work.
 
Upvote 0

Forum statistics

Threads
1,214,375
Messages
6,119,168
Members
448,870
Latest member
max_pedreira

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