Formula for chart

yitzymerm

New Member
Joined
Jul 7, 2022
Messages
14
Office Version
  1. 365
Platform
  1. Windows
Please see snapshot of ht & wt chart below, Column C is showing the height, Row 7 are the ages & Row 6 is the category result, and the weight amounts in the chart are the maximum allowed (i.e. Age 25, Height 4.8 can weigh up to 130 to fall into excellent category, at 131 lbs they are already in the 'good' category until 152 etc.)

I would like to be able to enter the Ht, Wt, & age in column B & the result should automatically come up in B4 (excellent, good or poor), please advise simplest & best formula that should be used.

Thanks in advance.

View attachment 80818
 

Excel Facts

Highlight Duplicates
Home, Conditional Formatting, Highlight Cells, Duplicate records, OK to add pink formatting to any duplicates in selected range.
Seems like the chart didn't upload well in original post, please see below.

1670970632562.png
 
Upvote 0
suggest you to use XL2BB Mini Sheet.
Your chart cells formats will affect how the formula work.
It's hard only by a picture.
 
Upvote 0
Try.
The formula in B4 is
=IF($B$2>VLOOKUP($B$1,$C$8:$J$28,7),"Poor",IF($B$2>HLOOKUP(B3,D7:H28,MATCH($B$1,$C$8:$C$28,0)+1,1),"Good","Excellent"))

The cells below "Excellent" should be replace by 20, 24, 30, 50, 60.
HTH.
身高體重.xlsm
ABCDEFGHIJ
1H4'8"
2W130
3Age24
4RESULTExcellent
5
6EXCELLENTGoodPoor
7H/A2024305060All agesAll ages
84'8"125130132136138152191
94'9"128132135139141155195
104'10"
114'11"
125'0"
135'1"
145'2"
155'3"
165'4"
175'5"
185'6"
195'7"
205'8"
215'9"
225'10"
235'11"
246'0"
256'1"
266'2"
276'3"
286'4"
工作表8 (2)
Cell Formulas
RangeFormula
B4B4=IF($B$2>VLOOKUP($B$1,$C$8:$J$28,7),"Poor",IF($B$2>HLOOKUP(B3,D7:H28,MATCH($B$1,$C$8:$C$28,0)+1,1),"Good","Excellent"))
 
Upvote 0
Here is a version that you can keep your titles "20-23", "24-29"...etc.
The formula in B4 is
=IF($B$2>VLOOKUP($B$1,$C$8:$J$28,7),"Poor",IF($B$2>INDEX($D$8:$H$28,MATCH($B$1,$C$8:$C$28,0),MATCH(B3,VALUE(LEFT($D$7:$H$7,2)),1)),"Good","Excellent"))

And you should press CTRL+SHIFT+ENTER to enter array formulas.
Good Luck.
身高體重.xlsm
ABCDEFGHIJ
1H4'9"
2W134
3Age30
4RESULTExcellent
5
6EXCELLENTGoodPoor
7H/A20-2324-2930-4950-5960+All agesAll ages
84'8"125130132136138152191
94'9"128132135139141155195
104'10"
114'11"
125'0"
135'1"
145'2"
155'3"
165'4"
175'5"
185'6"
195'7"
205'8"
215'9"
225'10"
235'11"
246'0"
256'1"
266'2"
276'3"
286'4"
工作表8 (3)
Cell Formulas
RangeFormula
B4B4=IF($B$2>VLOOKUP($B$1,$C$8:$J$28,7),"Poor",IF($B$2>INDEX($D$8:$H$28,MATCH($B$1,$C$8:$C$28,0),MATCH(B3,VALUE(LEFT($D$7:$H$7,2)),1)),"Good","Excellent"))
Press CTRL+SHIFT+ENTER to enter array formulas.
 
Upvote 0
suggest you to use XL2BB Mini Sheet.
Your chart cells formats will affect how the formula work.
It's hard only by a picture.
Hi HongRu,
Thanks so much for your help!!!
I have another chart which is a bit more complex than the previous one, would really appreciate if you can help me with this as well, on this one on highest rating it depends between male & female and on age, the other classes does not differ between gender and age, this chart has also much more levels, (want the rating result in cell B5 based on B1:B4 info).

I'll attach here the Mini Sheet so should be easier for you.

Buildchart.xlsx
ABCDEFGHIJKLMNOPQRSTUVWXY
1Enter M/FAges20-2425-2930-3940-4950-5960+20-2425-2930-3940-4950-5960+All Ages
2Enter HeightHt/RatingMale - EliteFemale - ElitePreferredStandardClass 2Class 3Class 4Class 6Class 8Class 10Class 12
3Enter Weight4.8128131132134136138124126130133134135151191202213222231240N/AN/A
4Enter Age4.9131133135137139141126130133136138138154195206217226235244N/AN/A
5Rating Result4.10135137139141143145131134137139141142158199210221230239249N/AN/A
64.11138140142144146148134137139142144145161203214224233243253N/AN/A
75141143145147149151136139142145147148165207218229239248257266275
85.1145147149151153155140143146149151152169212223233243252261270279
95.2147149152154156158143146149152154155172216227237247256265274283
105.3151153155158160162146149153156158159177221232243253263273282291
115.4156158160162165167151154157161162164183227238249260270280290299
125.5159162164166169171154158161164167168188233244255266277287297306
135.6164166169171174176159162166169171173192239250261272283294304313
145.7168170173175178181163166170173175177197245256268279290302312321
155.8171174176179182185166170173177179181202252264276287298310320329
165.9176179182185187190171174178183185186207259272284296307319329338
175.10182184187190192195175179184187190191212266279291303315326337347
185.11185188191194196199179184187191194195217273286299311323334345355
196191194197199202205185189193197199201223281294307319331342353363
206.1196199201204207210190194198202204206228289302315327339350362372
216.2199202205208211214193197202206208210235297310323335347358371381
226.3206209212215218221200204208212215217241305318331343355367380390
236.4212215218221224227205209214218221223248313326339351363376389399
246.5217220223227230234210215219224227228255321334347359372385398408
256.6224227230234238241217221226232235236263328342355367381394407417
266.7230235238241245248223228234238241243270336350363375390403416426
276.8238241245248252255229235240245248250
286.9243247250254257261236241246251254256
296.10249252256260263267241246251257260262
Sheet2 (3)
 
Upvote 0
Try.

B5
=IF(B3<=INDEX(IF($B$1="M",$E$3:$J$29,$K$3:$P$29),MATCH($B$2,$D$3:$D$29,0),MATCH($B$4,VALUE(LEFT($E$1:$J$1,2)),1)),"Elite",INDEX($Q$2:$Y$2,1,IFERROR(MATCH($B$3-1,OFFSET($Q2:$Y2,MATCH($B$2,$D$3:$D$29,0),0),1)+1,1)))

If not MS365, press CTRL+SHIFT+ENTER to enter array formulas.

The formula is long enough.
So I don't write more to prevent some errors from happening,
ex:
1.When weight more than the most class, it shows "#REF!".
2. Since Class10, Class12's "N/A" between height 4.8 to 4.11. (X3:Y6), the weight more than Class 8 shows "Class 10".
3. While the blank data in Height 6.9 to 6.10 and weight beyond elite (Q27:Y29) , it shows "Preferred".

PS. the cells "D5", "D17", D29" should be "4.10", "5.10", "6.10", not "4.1", "5.1", "6.1"
身高體重性別.xlsx
ABCDEFGHIJKLMNOPQRSTUVWXY
1Enter M/FMAges20-2425-2930-3940-4950-5960+20-2425-2930-3940-4950-5960+All Ages
2Enter Height5.10Ht/RatingMale - EliteFemale - ElitePreferredStandardClass 2Class 3Class 4Class 6Class 8Class 10Class 12
3Enter Weight2514.8128131132134136138124126130133134135151191202213222231240N/AN/A
4Enter Age254.9131133135137139141126130133136138138154195206217226235244N/AN/A
5Rating ResultStandard4.10135137139141143145131134137139141142158199210221230239249N/AN/A
64.11138140142144146148134137139142144145161203214224233243253N/AN/A
75141143145147149151136139142145147148165207218229239248257266275
85.1145147149151153155140143146149151152169212223233243252261270279
95.2147149152154156158143146149152154155172216227237247256265274283
105.3151153155158160162146149153156158159177221232243253263273282291
115.4156158160162165167151154157161162164183227238249260270280290299
125.5159162164166169171154158161164167168188233244255266277287297306
135.6164166169171174176159162166169171173192239250261272283294304313
145.7168170173175178181163166170173175177197245256268279290302312321
155.8171174176179182185166170173177179181202252264276287298310320329
165.9176179182185187190171174178183185186207259272284296307319329338
175.10182184187190192195175179184187190191212266279291303315326337347
185.11185188191194196199179184187191194195217273286299311323334345355
196191194197199202205185189193197199201223281294307319331342353363
206.1196199201204207210190194198202204206228289302315327339350362372
216.2199202205208211214193197202206208210235297310323335347358371381
226.3206209212215218221200204208212215217241305318331343355367380390
236.4212215218221224227205209214218221223248313326339351363376389399
246.5217220223227230234210215219224227228255321334347359372385398408
256.6224227230234238241217221226232235236263328342355367381394407417
266.7230235238241245248223228234238241243270336350363375390403416426
276.8238241245248252255229235240245248250
286.9243247250254257261236241246251254256
296.10249252256260263267241246251257260262
工作表1 (4)
Cell Formulas
RangeFormula
B5B5=IF(B3<=INDEX(IF($B$1="M",$E$3:$J$29,$K$3:$P$29),MATCH($B$2,$D$3:$D$29,0),MATCH($B$4,VALUE(LEFT($E$1:$J$1,2)),1)),"Elite",INDEX($Q$2:$Y$2,1,IFERROR(MATCH($B$3-1,OFFSET($Q2:$Y2,MATCH($B$2,$D$3:$D$29,0),0),1)+1,1)))
Press CTRL+SHIFT+ENTER to enter array formulas.
 
Upvote 0
Try.

B5
=IF(B3<=INDEX(IF($B$1="M",$E$3:$J$29,$K$3:$P$29),MATCH($B$2,$D$3:$D$29,0),MATCH($B$4,VALUE(LEFT($E$1:$J$1,2)),1)),"Elite",INDEX($Q$2:$Y$2,1,IFERROR(MATCH($B$3-1,OFFSET($Q2:$Y2,MATCH($B$2,$D$3:$D$29,0),0),1)+1,1)))

If not MS365, press CTRL+SHIFT+ENTER to enter array formulas.

The formula is long enough.
So I don't write more to prevent some errors from happening,
ex:
1.When weight more than the most class, it shows "#REF!".
2. Since Class10, Class12's "N/A" between height 4.8 to 4.11. (X3:Y6), the weight more than Class 8 shows "Class 10".
3. While the blank data in Height 6.9 to 6.10 and weight beyond elite (Q27:Y29) , it shows "Preferred".

PS. the cells "D5", "D17", D29" should be "4.10", "5.10", "6.10", not "4.1", "5.1", "6.1"
身高體重性別.xlsx
ABCDEFGHIJKLMNOPQRSTUVWXY
1Enter M/FMAges20-2425-2930-3940-4950-5960+20-2425-2930-3940-4950-5960+All Ages
2Enter Height5.10Ht/RatingMale - EliteFemale - ElitePreferredStandardClass 2Class 3Class 4Class 6Class 8Class 10Class 12
3Enter Weight2514.8128131132134136138124126130133134135151191202213222231240N/AN/A
4Enter Age254.9131133135137139141126130133136138138154195206217226235244N/AN/A
5Rating ResultStandard4.10135137139141143145131134137139141142158199210221230239249N/AN/A
64.11138140142144146148134137139142144145161203214224233243253N/AN/A
75141143145147149151136139142145147148165207218229239248257266275
85.1145147149151153155140143146149151152169212223233243252261270279
95.2147149152154156158143146149152154155172216227237247256265274283
105.3151153155158160162146149153156158159177221232243253263273282291
115.4156158160162165167151154157161162164183227238249260270280290299
125.5159162164166169171154158161164167168188233244255266277287297306
135.6164166169171174176159162166169171173192239250261272283294304313
145.7168170173175178181163166170173175177197245256268279290302312321
155.8171174176179182185166170173177179181202252264276287298310320329
165.9176179182185187190171174178183185186207259272284296307319329338
175.10182184187190192195175179184187190191212266279291303315326337347
185.11185188191194196199179184187191194195217273286299311323334345355
196191194197199202205185189193197199201223281294307319331342353363
206.1196199201204207210190194198202204206228289302315327339350362372
216.2199202205208211214193197202206208210235297310323335347358371381
226.3206209212215218221200204208212215217241305318331343355367380390
236.4212215218221224227205209214218221223248313326339351363376389399
246.5217220223227230234210215219224227228255321334347359372385398408
256.6224227230234238241217221226232235236263328342355367381394407417
266.7230235238241245248223228234238241243270336350363375390403416426
276.8238241245248252255229235240245248250
286.9243247250254257261236241246251254256
296.10249252256260263267241246251257260262
工作表1 (4)
Cell Formulas
RangeFormula
B5B5=IF(B3<=INDEX(IF($B$1="M",$E$3:$J$29,$K$3:$P$29),MATCH($B$2,$D$3:$D$29,0),MATCH($B$4,VALUE(LEFT($E$1:$J$1,2)),1)),"Elite",INDEX($Q$2:$Y$2,1,IFERROR(MATCH($B$3-1,OFFSET($Q2:$Y2,MATCH($B$2,$D$3:$D$29,0),0),1)+1,1)))
Press CTRL+SHIFT+ENTER to enter array formulas.
Thanks so much HongRu, you're the man!!!

Took me a while to fully understand the complex formula you wrote but works like a charm.

Now if i want to add let's say in cell B6 based on the result how much over the limit he was from the previous better rating, what formula would I put?

In example, Male age 20, Ht 5.5, Wt 165 which comes out "preferred" I want that cell to tell me how many LBS he was over, which in this case it would be 8 Lbs, as the limit for Elite is 157.

Thanks loads for all your help.
 
Upvote 0
In example, Male age 20, Ht 5.5, Wt 165 which comes out "preferred" I want that cell to tell me how many LBS he was over, which in this case it would be 8 Lbs, as the limit for Elite is 157.
157 and over 8?
Not 159 over 6?
 
Upvote 0
Try.

The formulas are too complex to debug.
So I am not sure the formula are all right.
And I make some conditional formats to check values easily.

Book.xlsx
ABCDEFGHIJKLMNOPQRSTUVWXY
1Enter M/FMAges20-2425-2930-3940-4950-5960+20-2425-2930-3940-4950-5960+All Ages
2Enter Height5.1Ht/RatingMale - EliteFemale - ElitePreferredStandardClass 2Class 3Class 4Class 6Class 8Class 10Class 12
3Enter Weight2234.8128131132134136138124126130133134135151191202213222231240N/AN/A
4Enter Age604.9131133135137139141126130133136138138154195206217226235244N/AN/A
5Rating ResultClass 24.10135137139141143145131134137139141142158199210221230239249N/AN/A
6Better Rate114.11138140142144146148134137139142144145161203214224233243253N/AN/A
75141143145147149151136139142145147148165207218229239248257266275
85.1145147149151153155140143146149151152169212223233243252261270279
95.2147149152154156158143146149152154155172216227237247256265274283
105.3151153155158160162146149153156158159177221232243253263273282291
115.4156158160162165167151154157161162164183227238249260270280290299
125.5159162164166169171154158161164167168188233244255266277287297306
135.6164166169171174176159162166169171173192239250261272283294304313
145.7168170173175178181163166170173175177197245256268279290302312321
155.8171174176179182185166170173177179181202252264276287298310320329
165.9176179182185187190171174178183185186207259272284296307319329338
175.10182184187190192195175179184187190191212266279291303315326337347
185.11185188191194196199179184187191194195217273286299311323334345355
196191194197199202205185189193197199201223281294307319331342353363
206.1196199201204207210190194198202204206228289302315327339350362372
216.2199202205208211214193197202206208210235297310323335347358371381
226.3206209212215218221200204208212215217241305318331343355367380390
236.4212215218221224227205209214218221223248313326339351363376389399
246.5217220223227230234210215219224227228255321334347359372385398408
256.6224227230234238241217221226232235236263328342355367381394407417
266.7230235238241245248223228234238241243270336350363375390403416426
276.8238241245248252255229235240245248250
286.9243247250254257261236241246251254256
296.10249252256260263267241246251257260262
Sheet(2)
Cell Formulas
RangeFormula
B5B5=IF(B3<=INDEX(IF($B$1="M",$E$3:$J$29,$K$3:$P$29),MATCH($B$2,$D$3:$D$29,0),MATCH($B$4,VALUE(LEFT($E$1:$J$1,2)),1)),"Elite",INDEX($Q$2:$Y$2,1,IFERROR(MATCH($B$3-1,OFFSET($Q2:$Y2,MATCH($B$2,$D$3:$D$29,0),0),1)+1,1)))
B6B6=IF($B$3<=INDEX($Q$3:$Q$29,MATCH($B$2,$D$3:$D$29,0)),B3-INDEX(IF($B$1="M",$E$3:$J$29,$K$3:$P$29),MATCH($B$2,$D$3:$D$29,0),MATCH($B$4,VALUE(LEFT($E$1:$J$1,2)),1)),IF(INDEX($Q$3:$Y$29,MATCH($B$2,$D$3:$D$29,0),IFERROR(MATCH($B$3-1,OFFSET($Q2:$Y2,MATCH($B$2,$D$3:$D$29,0),0),1),1))="",$B$3-INDEX(IF($B$1="M",$E$3:$J$29,$K$3:$P$29),MATCH($B$2,$D$3:$D$29,0),MATCH($B$4,VALUE(LEFT($E$1:$J$1,2)),1)),$B$3-INDEX($Q$3:$Y$29,MATCH($B$2,$D$3:$D$29,0),IFERROR(MATCH($B$3-1,OFFSET($Q2:$Y2,MATCH($B$2,$D$3:$D$29,0),0),1),1))))
Press CTRL+SHIFT+ENTER to enter array formulas.
Cells with Conditional Formatting
CellConditionCell FormatStop If True
Q2:Y2Expression=$B$5=Q$2textNO
Q2:Y2Expression=$D2=$B$2textNO
Q3:Y29Expression=$B$5=Q$2textNO
P1,J1,J3:J29,P3:P29Expression=$B$4>=VALUE(LEFT(J$1,2))textNO
E1:P1,E3:P29,E2,K2Expression=IFERROR(AND($B$4>=VALUE(LEFT(E$1,2)),$B$4<=VALUE(RIGHT(E$1,2))),FALSE)textNO
D3:Y29Expression=$D3=$B$2textNO
 
Upvote 0
Solution

Forum statistics

Threads
1,215,459
Messages
6,124,948
Members
449,198
Latest member
MhammadishaqKhan

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