Please Note: This article is written for users of the following Microsoft Excel versions: 2007, 2010, 2013, 2016, 2019, and Excel in Microsoft 365. If you are using an earlier version (Excel 2003 or earlier), this tip may not work for you. For a version of this tip written specifically for earlier versions of Excel, click here: Adjusting Test Scores Proportionately.
Written by Allen Wyatt (last updated April 10, 2021)
This tip applies to Excel 2007, 2010, 2013, 2016, 2019, and Excel in Microsoft 365
Mike is a teacher and often has to give tests to his students. In one instance he had 20 test scores that range from 76 down to 12. Mike wants to leave the top score at 76 but increase the bottom score by 5 (to 17) and then adjust all the in-between scores proportionately. He wonders if Excel has a function that will accomplish the adjustment for him.
There is no function that will do this, but there are any number of formulas that can be used to get the adjusted test scores. In fact, there are a surprisingly large number of formulas you can use. The reason why there are so many is because the word "proportionally" is ambiguous—what, exactly, does a proportional adjustment look like?
For instance, it could mean a portion of the difference between the lowest score and the highest score. Or, it could mean that the lower scores are "weighted" in some way so that they get a larger boost than the higher scores. Or, it could mean that you simply calculate what percentage the score is from the maximum score and then increase the score by that much.
With that in mind, let's look at a few ways you can adjust the scores. You'll want to look at the results of each formula and determine if they match your expectations for what should happen to the scores. These three formulas produce exactly the same adjustments to the scores, with the lower scores weighted more favorably than the higher scores:
=A1+(1-(A1-MIN(A:A))/(MAX(A:A)-MIN(A:A)))*5 =A1+(5*(MAX(A:A)-A1))/(MAX(A:A)-MIN(A:A)) =A1+(MAX(A:A)-A1)/(MAX(A:A)-MIN(A:A))*5
These formulas adjust the highest and lowest scores as required by Mike, and all other scores proportionally. It results, for example, in the mid-range score (half way between 12 and 76, which is a score of 42) being adjusted by 2.5 points.
The following simple formula only pays attention to the maximum value in the range of original scores. It calculates how far from the maximum the score is, and then adjusts the score upward. It results in a bottom adjusted score of 17.33, but that can be easily rounded to get to the desired amount.
=((MAX(A:A)-A1)/A1)+A1
The following formula examines the ranking of the original 19 scores, on a scale of 0 through 19. It then figures out what percentage of 5 that ranking represents and then adds the value to the original score:
=(RANK(A1,A:A)-1)*5/19+A1
You can also use linear regression to solve the problem. Excel has two built-in functions (SLOPE and INTERCEPT) that can be utilized to find the formula to determine the adjusted scores. In Mike's instance, the range of scores prior to adjustment is 12 to 76. These need to be adjusted to a range of 17 to 76. If you put 12 into cell E1, 76 into cell E2, 17 into cell F1, and 76 into cell F2, then you end up with the lows and highs in both the starting and ending ranges. You can then use these formulas to find the slope and intercept:
=SLOPE(F1:F2,E1:E2) =INTERCEPT(F1:F2,E1:E2)
This calculates the slope at 0.921875 and the intercept at 5.9375. You can then apply these values to the original test scores in this manner:
=0.921875 * A1 + 5.9375
Interestingly enough, this linear regression approach returns the exact same values derived by the first three formulas presented at the beginning of this tip.
ExcelTips is your source for cost-effective Microsoft Excel training. This tip (1024) applies to Microsoft Excel 2007, 2010, 2013, 2016, 2019, and Excel in Microsoft 365. You can find a version of this tip for the older menu interface of Excel here: Adjusting Test Scores Proportionately.
Solve Real Business Problems Master business modeling and analysis techniques with Excel and transform data into bottom-line results. This hands-on, scenario-focused guide shows you how to use the latest Excel tools to integrate data from multiple tables. Check out Microsoft Excel 2013 Data Analysis and Business Modeling today!
Using a formula to find information in a text value is easy. Using a formula to find either of two text values within a ...
Discover MoreLooking for a formula that can return the address of a cell containing a text string? Look no further; the solution is in ...
Discover MoreISBN numbers are used to denote a unique identifier for a published book. If you remove the dashes included in an ISBN, ...
Discover MoreFREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
There are currently no comments for this tip. (Be the first to leave your comment—just use the simple form above!)
Got a version of Excel that uses the ribbon interface (Excel 2007 or later)? This site is for you! If you use an earlier version of Excel, visit our ExcelTips site focusing on the menu interface.
FREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
Copyright © 2024 Sharon Parq Associates, Inc.
Comments