match, find and round to nearest number

coccio

Board Regular
Joined
Mar 19, 2002
Messages
143
<html><head><title>Excel Jeanie HTML</title></head><body>
Excel Workbook
ABCDEFGHIJ
1BMI*19202122*FtInlbs
2FtInBody Weight*41099
34109196100105****
44119499104109****
55097102107112***BMI
6**********
Sheet


</body></html>
I want to match H2 & I2 to columns A3:A5 & B3:B5 and in J3 I want to be able round to the nearest number like in this case it would be 100. In J6 it would show a BMI of 21. If J2 was 97 then the BMI would be 20.
Anyone know how to do that?
 

Excel Facts

How to show all formulas in Excel?
Press Ctrl+` to show all formulas. Press it again to toggle back to numbers. The grave accent is often under the tilde on US keyboards.

barry houdini

MrExcel MVP
Joined
Mar 23, 2005
Messages
20,825
Isn't there a direct calculation you can do to get BMI based on height and weight? You could calculate without a table.....i.e.

=ROUND(J2*4.88/(H2+I2/12)^2,0)

although I can't guarantee that will give you the same results as your table in all cases.

Using the table you can use this formula in J6

=INDEX(C1:F1,MATCH(MIN(ABS(INDEX(C3:F5,MATCH(1,(A3:A5=H2)*(B3:B5=I2),0),0)-J2)),ABS(INDEX(C3:F5,MATCH(1,(A3:A5=H2)*(B3:B5=I2),0),0)-J2),0))

confirmed with CTRL+SHIFT+ENTER
 

coccio

Board Regular
Joined
Mar 19, 2002
Messages
143
There might be a calculation but I don't know of one. The table formula is working great..thanks

Isn't there a direct calculation you can do to get BMI based on height and weight? You could calculate without a table.....i.e.

=ROUND(J2*4.88/(H2+I2/12)^2,0)

although I can't guarantee that will give you the same results as your table in all cases.

Using the table you can use this formula in J6

=INDEX(C1:F1,MATCH(MIN(ABS(INDEX(C3:F5,MATCH(1,(A3:A5=H2)*(B3:B5=I2),0),0)-J2)),ABS(INDEX(C3:F5,MATCH(1,(A3:A5=H2)*(B3:B5=I2),0),0)-J2),0))

confirmed with CTRL+SHIFT+ENTER
 

coccio

Board Regular
Joined
Mar 19, 2002
Messages
143
FYI the formula is this..

BMI = W*703/H^2, W in pounds, H in inches
 

barry houdini

MrExcel MVP
Joined
Mar 23, 2005
Messages
20,825
That was essentially the formula I suggested, i.e.

=ROUND(J2*4.88/(H2+I2/12)^2,0)

because feet are squared in my version rather than inches then multiplier is 4.88 rather than 703 because

144*4.88= 703 [almost]

to revise that formula for your version

=ROUND(J2*703/(H2*12+I2)^2,0)
 
Master Excel Bundle

Excel contains over 450 functions, with more added every year. That’s a huge number, so where should you start? Right here with this bundle.

Forum statistics

Threads
1,164,426
Messages
5,837,165
Members
430,480
Latest member
iangessey

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
Top