Convert a series of numbers to a 1 to 5 scale relative to the highest and lowest

mazssj

New Member
Joined
Jan 7, 2014
Messages
5
I have a series of numbers ranging from 75 to 90 (as an example) and I want each of these numbers to converted or related to a scale of 1 to 5.
75 because it's the lowest value it should be an 1, 90 because it's highest value should be 5.

Thanks
 

Excel Facts

Lock one reference in a formula
Need 1 part of a formula to always point to the same range? use $ signs: $V$2:$Z$99 will always point to V2:Z99, even after copying
With
A1: ...a number between 75 and 90, inclusive

This regular formula categorizes that number between 1 and 5
B1: =MAX(CEILING((A1-75)/3,1),1)

Is that something you can work with?
 
Upvote 0
Thank you for your response. Got me a bit close than I was earlier.

TzJoNp9.png


This is what I get using a random example, I don't want the values on B to be higher than 5.
 
Upvote 0
My apologies...You indicated that the numbers would be constrained between 75 and 90.
Try this regular formula:
=MIN(MAX(CEILING((A1-75)/3,1),1),5)

Does that help?
 
Upvote 0
Worked well for my first 4 series of numbers when I did the 5th series, I got this:
eQcs0TA.png

83 is the highest number and it should be an 5 not a 4.
 
Upvote 0
I'm guessing that what you *meant* to say, originally, is that you want to rank a series of numbers between the minumum and maximum values for that series, right?

Assuming that's correct, put this regular formula in B1 and copy it down as far as you need:
=IF(A1="","",MIN(MAX(CEILING((A1-MIN(A:A))/((MAX(A:A)-MIN(A:A))/5),1),1),5))

Does that help?
 
Upvote 0
I'm guessing that what you *meant* to say, originally, is that you want to rank a series of numbers between the minumum and maximum values for that series, right?

Assuming that's correct, put this regular formula in B1 and copy it down as far as you need:
=IF(A1="","",MIN(MAX(CEILING((A1-MIN(A:A))/((MAX(A:A)-MIN(A:A))/5),1),1),5))

Does that help?


Thats what I meant, not a native english speaker , sometimes I don't express myself properly :(

Worked now, thank you for your help.
 
Upvote 0
A small modification in Ron's formula:

Code:
=IF(A1="","",CEILING((A1-MIN(A:A)+(A1=MIN(A:A)))/((MAX(A:A)-MIN(A:A))/5),1))

Markmzz
 
Upvote 0

Forum statistics

Threads
1,213,491
Messages
6,113,963
Members
448,536
Latest member
CantExcel123

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