Taking performance goals, converting to scale 0 - 10

Speedo

New Member
Joined
Aug 22, 2018
Messages
9
So i have had several Microsoft Techs try to solve this and while we seem to get close, something is missing. I have a spreadsheet that takes employee standards and attempts to score the standards on a scale from 0 - 10. For example

https://www.facebook.com/photo.php?fbid=1628675570594681&set=a.1628676030594635&type=3&theater

The formula looks like this:

=IF(M9="","",IF(M9<H9,3.99*((M9/H9)*100)/100,IF(AND(M9>=H9,M9<I9),5.99*((M9/I9)*100)/100,IF(AND(M9>=I9,M9<J9),7.99*((M9/J9)*100)/100,IF(AND(M9>=J9,M9<K9),9.99*((M9/K9)*100)/100,10)))))

When I do the math with a calculator, I come up with the result shown in N9, but it is not the result I would expect. M9 happens to be exactly 90.000, So I would expect the scaling to return exactly 4.000, NOT 5.776.

Anyway, I have been working on this formula for years, but no one has been able to get it to work. The break points of G9, H9, I9, J9, K9 are there to show milestone in performance and N9 changes colors from Blank, Green, Blue, Purple, Gold.

I have 2 other example cells where this calculation returns a number not expected in N9.

Thank you guys for any time and interest of this project.

Speed
 

Excel Facts

Will the fill handle fill 1, 2, 3?
Yes! Type 1 in a cell. Hold down Ctrl while you drag the fill handle.
I do not see an edit, but the formula looks like thins

=IF(M9="","",IF(M9<H9,3.99*((M9/H9)*100)/100,IF(AND(M9>=H9,M9<I9),5.99*((M9/I9)*100)/100,IF(AND(M9>=I9,M9<J9),7.99*((M9/J9)*100)/100,IF(AND(M9>=J9,M9<K9),9.99*((M9/K9)*100)/100,10)))))
 
Upvote 0
Welcome to the forum.

First, the forum is probably cutting off your formula since it has a < or > in it. Typically, the forum interprets that as an HTML tag (formatting information), and doesn't treat it as a real "less than" sign. To get around that, put a space before and after each < or > in your formula. An alternate method is to turn off HTML code when you create the thread.

Next, if you want to post a sample sheet, try using one of the HTML creation tools (see the link in my signature). Or you can post the workbook to a public file sharing site and post the link. However, some people can't or won't download files from the internet for various reasons, so that limits your audience. And some people (like me) don't have Facebook, so that's even less desirable.

Finally, from what I see of your formula, it's not formatted properly, so I'm not surprised it doesn't give you the answer you want. If you show the rest of it, we can look at it.

Good luck!
 
Upvote 0
Full formula:

=IF(M9="","",IF(M9<H9,3.99*((M9/H9)*100)/100,IF(AND(M9>=H9,M9<I9),5.99*((M9/I9)*100)/100,IF(AND(M9>=I9,M9<J9),7.99*((M9/J9)*100)/100,IF(AND(M9>=J9,M9<K9),9.99*((M9/K9)*100)/100,10)))))

?
 
Upvote 0
Thank you for being kind to this rookie on a forum.

Trying to show picture:
VgOeJjaCMakG6fL3oW7NbiVOPsQ5mjMOA4QYUCn76d5AJqmXGjkTiToZXWminfTKM0FTpN7qQ-U4B3lP6jo6-8yChi5L4FpmSBkYPYoEd7i7MmWhA82DCoWC67ID8KsMRTzdUK6_-lZYL4Icim5rXUElX-GeA9-bzo7YlnrnxctDlyp5GwkW9NMvI6z3OYtSCOUMhvEVqorRUqdjqLIST34v2qL-iommw_82GpgT977seMs00r2KZz-MvE_MW5ceaE4kzf18aVxtSyKvVcjiyIWdO0IaepkeDfLlbXN0gVib2wFxclbKZHtJ2kXaoPke7rPXvZa1N5HfphJmh7KSjkQnoiUriiXcv2FKIbd-wM-a05UKP-FAzfyDv3uxhSF-0iYRSrZrxhenyRuK89cJhNdO6vvAnpOp6SYJB70MkdcCn5A0_3AaCZG5s3sCNkeXyBkLB6A4FsrlMYPEha97KR9hEYQlNzFijAjcrYG4jCFi4RYStKc4omOqRddcUs4NnUwuYRsSV8wBYhWtOA60qWPBxIQo6Vgyk15q45_4Aexoy1B5666DCPjc9xnGDB18yEAv2WYTYN7pQVl7k-3CGPaGaCHEqDhm9fBK_g=w1784-h966-no
 
Upvote 0
@dreid1011 , thanks for digging out the formula.
@Speedo, I still can't see the picture, but based on the formula, I have a few thoughts. First, multiplying by 100 and dividing by 100 cancels out, so your equations can be simplified. Second, when you have a tiered function like this, it's usually better to use a MATCH or LOOKUP function to separate the tiers, instead of a long IF(AND ... formula. For example:



GHIJKLMN
90255075100505.326667
100.15960.11980.1065330.0999#DIV/0!5.326667

<tbody>
</tbody>
Sheet1

Worksheet Formulas
CellFormula
G10=3.99/H9
H10=5.99/I9
I10=7.99/J9
J10=9.99/K9
K10=1/0
N9=IF(M9="","",IF(M9< H9,3.99*((M9/H9>)*100)/100,IF(AND(M9>=H9,M9< I9),5.99*((M9/I9)*100)/100,IF(AND(M9>=I9,M9< J9),7.99*((M9/J9)*100)/100,IF(AND(M9>=J9,M9< K9),9.99*((M9/K9)*100)/100,10)))))
N10=IFERROR(IF(M9="","",M9*HLOOKUP(M9,G9:K10,2)),10)

<tbody>
</tbody>

<tbody>
</tbody>



Your formula is in N9. I added the values in G9 and the formulas in G10:K10, which enormously simplifies the formula in N10, which generates the same results as N9. Since I couldn't see the picture, I just put test values in H9:K9.

Finally, it might be easier to explain what you want to accomplish. Based on some testing, this formula generally rises as the value in M9 rises, but it dips at each of the tiers and starts to rise again. Is that what you want?
 
Upvote 0
@Eric W I noticed the *100/100 a while back, but when I try to remove the redundancy, I get other errors.

The best way that I can explain what I'm hoping to accomplish... Suppose you have a goal to solve peoples Excel problems of 100% success. If you achieve 100% success you would consider that "Best" would score a 10.000. Also, you may consider what a minimum standard of success before you (or a supervisor) would consider inadequate performance, say < 90%... So in my sheet "BDC Standards," G9 would be performance that is non satisfactory and considered a Caution. H9 would be that minimum standard, and K9 mean Best or world class.... So our example for a Microsoft Tech of 80% minimum standard that would be used in H9, anything lower than 40% would score in N9 and score (on a scale from 1 - 10) something in between 0.000 - 4.000. While anything 100% would achieve a score of 10. So the formula that I am hoping to solve here in N9, is to score someones performance on a scale from 0 - 10. M9 (actual) = 90.000 should score 4.000, NOT 5.776.

Screen shots continue to be a mystery to me, so here is a copy/paste so anyone can see the way I'm trying to show the information...

G
H
I
J
KL M
N
July-2018
0 - 3.994-5.99
6-7.99
8-9.99
10
ActualScore
9Achieve100.00%Responded to Goal #2 (0.13 Hrs)
<90.000
90.00093.33396.667100.00090.0005.776

<colgroup><col><col><col><col><col><col span="5"><col><col span="2"></colgroup><tbody>
</tbody>


Again, sincerely appreciate the time you guys are giving to me!
 
Upvote 0
@Eric W I noticed the *100/100 a while back, but when I try to remove the redundancy, I get other errors.

The best way that I can explain what I'm hoping to accomplish... Suppose you have a goal to solve peoples Excel problems of 100% success. If you achieve 100% success you would consider that "Best" would score a 10.000. Also, you may consider what a minimum standard of success before you (or a supervisor) would consider inadequate performance, say < 90%... So in my sheet "BDC Standards," G9 would be performance that is non satisfactory and considered a Caution. H9 would be that minimum standard, and K9 mean Best or world class.... So our example for a Microsoft Tech of 90% minimum standard that would be used in H9, anything lower than 40% would score in N9 and score (on a scale from 1 - 10) something in between 0.000 - 4.000. While anything 100% would achieve a score of 10. So the formula that I am hoping to solve here in N9, is to score someones performance on a scale from 0 - 10. M9 (actual) = 90.000 should score 4.000, NOT 5.776.

Screen shots continue to be a mystery to me, so here is a copy/paste so anyone can see the way I'm trying to show the information...

G H I JKL M N
July-20180 - 3.994-5.996-7.998-9.99 10ActualScore
9Achieve100.00%Responded to Goal #2 (0.13 Hrs) <90.00090.00093.33396.667100.00090.0005.776

<tbody>
</tbody>


Again, sincerely appreciate the time you guys are giving to me!

I changed the quote because i used 80% , but should have been 90%
 
Upvote 0
Probably easiest to build a table, and have the formula scale each tier based on the table:

Excel 2012
MNOPQR
1TableLowHigh
2003.99
39045.99
493.33367.99
596.66789.99
61001010
7
8ScoreRating
9904

<tbody>
</tbody>
Sheet1

Worksheet Formulas
CellFormula
N9=(M9-LOOKUP(M9,$P$2:$P$6))/(INDEX($P$3:$P$7,MATCH(M9,$P$2:$P$6))-LOOKUP(M9,$P$2:$P$6))*(VLOOKUP(M9,$P$2:$R$6,3)-VLOOKUP(M9,$P$2:$R$6,2))+VLOOKUP(M9,$P$2:$R$6,2)

<tbody>
</tbody>

<tbody>
</tbody>



You can simplify the formula a bit if you add another column to the table:

Excel 2012
MNOPQRS
1TableLowHighScaling factor
2003.990.044333
39045.990.59706
493.33367.990.596881
596.66789.990.59706
610010100
7
8ScoreRating
9883.901333

<colgroup><col style="width: 25pxpx"><col><col><col><col><col><col><col></colgroup><thead>
</thead><tbody>
</tbody>
Sheet1

Worksheet Formulas
CellFormula
S2=(R2-Q2)/(P3-P2)
S3=(R3-Q3)/(P4-P3)
S4=(R4-Q4)/(P5-P4)
S5=(R5-Q5)/(P6-P5)
S6=(R6-Q6)/(P7-P6)
N9=(M9-LOOKUP(M9,$P$2:$P$6))*VLOOKUP(M9,$P$2:$S$6,4)+VLOOKUP(M9,$P$2:$R$6,2)

<thead>
</thead><tbody>
</tbody>

<tbody>
</tbody>
 
Upvote 0

Forum statistics

Threads
1,214,591
Messages
6,120,428
Members
448,961
Latest member
nzskater

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