applying rounding formula to entire worksheet

  • Thread starter Thread starter Guest
  • Start date Start date
G

Guest

Hi, I have worksheet full of prices that I want to round to the nearest
multiple of 10 then subtract 1 to get a nice price with 9 on the end. (having
already multiplied the original numbers by a percent to change currencies)

I know how to make $47 into $49 by using =mround(47,10)-1 but how do I
apply it to the whole sheet? Paste special > Formulas is not working for me...

Thanks
 
Hi mateo,

You can do it with a macro like the following, which will add a formula to any
selected cells, regardless of whether they hold formulae or values. Just be
careful not to run it against cells containing text!

Sub RoundDownRange()
Dim OldVal As Object
Dim NewVal As String
For Each OldVal In Selection
NewVal = OldVal.Formula
If Left(NewVal, 1) = "=" Then
NewVal = Right(NewVal, Len(NewVal) - 1)
End If
NewVal = "=ROUND(" & NewVal & ",-1)-1"
OldVal.Formula = NewVal
Next OldVal
End Sub

Cheers
 
To round all numbers to nearest 10:

Select tools > calculation > Precision as displayed then format > cells
number > custom "#,.00".

(Switch ",." to ".," for European settings). It's probably best to copy
data to a new workbook first and then paste back as formulas only.

To subtract 1 from cells:

Enter 1 in a cell copy, edit > goto > special > constants > numbers and
Edit > paste Special > Values and Subtract.
 
This works great but is too tedious because of need to select each price
group separately to avoid text.

macropod said:
Hi mateo,

You can do it with a macro like the following, which will add a formula to any
selected cells, regardless of whether they hold formulae or values. Just be
careful not to run it against cells containing text!

Sub RoundDownRange()
Dim OldVal As Object
Dim NewVal As String
For Each OldVal In Selection
NewVal = OldVal.Formula
If Left(NewVal, 1) = "=" Then
NewVal = Right(NewVal, Len(NewVal) - 1)
End If
NewVal = "=ROUND(" & NewVal & ",-1)-1"
OldVal.Formula = NewVal
Next OldVal
End Sub

Cheers

--
macropod
[MVP - Microsoft Word]


mateo said:
Hi, I have worksheet full of prices that I want to round to the nearest
multiple of 10 then subtract 1 to get a nice price with 9 on the end. (having
already multiplied the original numbers by a percent to change currencies)

I know how to make $47 into $49 by using =mround(47,10)-1 but how do I
apply it to the whole sheet? Paste special > Formulas is not working for me...

Thanks
 
hi, thanks.

first, you must be using a different version of excel than me because "tools
calculation" doesn't exist on my excel 2003. If I highlight on a cell then
right click, I can choose Format cells. When I go to custom and add "#,.00"
all it does is output a value with two decimal places. -- not round to the
nearest 10. please advise.
 
Hi mateo,

Had you mentioned there being an issue with text & values being interspersed, I might have suggested using:

Sub RoundDownRange()
Dim OldVal As Object
Dim NewVal As String
For Each OldVal In Selection
If Application.WorksheetFunction.IsNumber(OldVal.Value) Then
NewVal = OldVal.Formula
If Left(NewVal, 1) = "=" Then
NewVal = Right(NewVal, Len(NewVal) - 1)
End If
NewVal = "=ROUND(" & NewVal & ",-1)-1"
OldVal.Formula = NewVal
End If
Next OldVal
End Sub

Although the code does what you asked for, the results are a bit odd (ie -1) if the starting value is less than 5.

Cheers

--
macropod
[MVP - Microsoft Word]


| This works great but is too tedious because of need to select each price
| group separately to avoid text.
|
| "macropod" wrote:
|
| > Hi mateo,
| >
| > You can do it with a macro like the following, which will add a formula to any
| > selected cells, regardless of whether they hold formulae or values. Just be
| > careful not to run it against cells containing text!
| >
| > Sub RoundDownRange()
| > Dim OldVal As Object
| > Dim NewVal As String
| > For Each OldVal In Selection
| > NewVal = OldVal.Formula
| > If Left(NewVal, 1) = "=" Then
| > NewVal = Right(NewVal, Len(NewVal) - 1)
| > End If
| > NewVal = "=ROUND(" & NewVal & ",-1)-1"
| > OldVal.Formula = NewVal
| > Next OldVal
| > End Sub
| >
| > Cheers
| >
| > --
| > macropod
| > [MVP - Microsoft Word]
| >
| >
| > | > > Hi, I have worksheet full of prices that I want to round to the nearest
| > > multiple of 10 then subtract 1 to get a nice price with 9 on the end. (having
| > > already multiplied the original numbers by a percent to change currencies)
| > >
| > > I know how to make $47 into $49 by using =mround(47,10)-1 but how do I
| > > apply it to the whole sheet? Paste special > Formulas is not working for me...
| > >
| > > Thanks
| >
| >
| >
 
I was not clear, use tools > options and check the precision as
displayed box on the calculation tab you will get a message saying data
will lose accuracy then click OK. You can try this out in a new
workbook and then paste back without formatting.
 
Or perhaps this revised edition which will change just formulas only.

Sub RoundDownRange()
Dim OldVal As Object
Dim NewVal As String
For Each OldVal In Selection
If OldVal.HasFormula = True Then
If Not OldVal.Formula Like "=ROUND(*" Then
NewVal = OldVal.Formula
If Left(NewVal, 1) = "=" Then
NewVal = Right(NewVal, Len(NewVal) - 1)
End If
NewVal = "=ROUND(" & NewVal & ",-1)-1"
OldVal.Formula = NewVal
End If
End If
Next OldVal
End Sub


Gord Dibben MS Excel MVP
 
Hi mateo,

It doesn't behave that way for me. On my system, it processes all cells containing only numeric values, or formulae that return
numeric values, and skips any other cells (eg empty cells and cells with text). Merged cells have no effect - the code processes
them just the same as it does with un-merged cells.

Did you modify the code in any way?

Cheers

--
macropod
[MVP - Microsoft Word]


| Thanks for that Macropod, I should have mention the text titles. For some
| reason when running your new macro after selecting everything it either says
| "this macro requires merge cells to be of the same size." Or when just
| selecting numbers, it make each row contain the same number as the first cell
| in each row.
|
|
| "macropod" wrote:
|
| > Hi mateo,
| >
| > Had you mentioned there being an issue with text & values being interspersed, I might have suggested using:
| >
| > Sub RoundDownRange()
| > Dim OldVal As Object
| > Dim NewVal As String
| > For Each OldVal In Selection
| > If Application.WorksheetFunction.IsNumber(OldVal.Value) Then
| > NewVal = OldVal.Formula
| > If Left(NewVal, 1) = "=" Then
| > NewVal = Right(NewVal, Len(NewVal) - 1)
| > End If
| > NewVal = "=ROUND(" & NewVal & ",-1)-1"
| > OldVal.Formula = NewVal
| > End If
| > Next OldVal
| > End Sub
| >
| > Although the code does what you asked for, the results are a bit odd (ie -1) if the starting value is less than 5.
| >
| > Cheers
| >
| > --
| > macropod
| > [MVP - Microsoft Word]
| >
| >
|
 
No, did not modify. Tried again multiple times, the original still works fine
though, and thinking about how I will be referencing each table individually
when going back and forth from the destination webpage, I realize that
rounding each table individually using your original formula is not a problem
at all. Thanks Macropod.

If you care to write one that can start from the very beginning in one step
allowing for a bunch of text thrown into the tables, that would be great.
Converting currencies and then rounding to the nearest nine.

an example: I need to change $4699CAD into $3099Euro using the conversion
rate of 0.66. A macro that could easily adapt to different currencies by
throwing in the percentile would be great.

Cheers
M
 
To process the whole worksheet, you could use something like:

Sub RoundDownSheet()
Dim OldVal As Object
Dim NewVal As String
Dim ConvRate
ConvRate = InputBox("What is the conversion rate?", "Currency Conversion", 1)
On Error GoTo Abort
For Each OldVal In ActiveSheet.UsedRange
If Application.WorksheetFunction.IsNumber(OldVal.Value) Then
NewVal = OldVal.Formula
If Left(NewVal, 1) = "=" Then
NewVal = Right(NewVal, Len(NewVal) - 1)
End If
NewVal = "=ROUND(" & NewVal & "*" & ConvRate & ",-1)-1"
OldVal.Formula = NewVal
End If
Next OldVal
Abort:
End Sub

This version includes a prompt for the currency conversion rate. If you don't want to apply the same conversion rate throughout the
worksheet, you'll need to change 'ActiveSheet.UsedRange' to 'Selection' and select the range the macro is to apply to. The new
formula retains both the original value and the conversion rate.

Cheers

--
macropod
[MVP - Microsoft Word]


| No, did not modify. Tried again multiple times, the original still works fine
| though, and thinking about how I will be referencing each table individually
| when going back and forth from the destination webpage, I realize that
| rounding each table individually using your original formula is not a problem
| at all. Thanks Macropod.
|
| If you care to write one that can start from the very beginning in one step
| allowing for a bunch of text thrown into the tables, that would be great.
| Converting currencies and then rounding to the nearest nine.
|
| an example: I need to change $4699CAD into $3099Euro using the conversion
| rate of 0.66. A macro that could easily adapt to different currencies by
| throwing in the percentile would be great.
|
| Cheers
| M
|
|
|
| "macropod" wrote:
|
| > Hi mateo,
| >
| > It doesn't behave that way for me. On my system, it processes all cells containing only numeric values, or formulae that return
| > numeric values, and skips any other cells (eg empty cells and cells with text). Merged cells have no effect - the code processes
| > them just the same as it does with un-merged cells.
| >
| > Did you modify the code in any way?
| >
| > Cheers
| >
| > --
| > macropod
| > [MVP - Microsoft Word]
| >
| >
| > | Thanks for that Macropod, I should have mention the text titles. For some
| > | reason when running your new macro after selecting everything it either says
| > | "this macro requires merge cells to be of the same size." Or when just
| > | selecting numbers, it make each row contain the same number as the first cell
| > | in each row.
| > |
| > |
|
 
You're welcome

Cheers

--
macropod
[MVP - Microsoft Word]


| Wow, it works great. Thank you very much, Macropod! I hope someone else gets
| to discover this info someday.
|
| Cheers!
| Mateo
|
|
|
| "macropod" wrote:
|
| > To process the whole worksheet, you could use something like:
| >
| > Sub RoundDownSheet()
| > Dim OldVal As Object
| > Dim NewVal As String
| > Dim ConvRate
| > ConvRate = InputBox("What is the conversion rate?", "Currency Conversion", 1)
| > On Error GoTo Abort
| > For Each OldVal In ActiveSheet.UsedRange
| > If Application.WorksheetFunction.IsNumber(OldVal.Value) Then
| > NewVal = OldVal.Formula
| > If Left(NewVal, 1) = "=" Then
| > NewVal = Right(NewVal, Len(NewVal) - 1)
| > End If
| > NewVal = "=ROUND(" & NewVal & "*" & ConvRate & ",-1)-1"
| > OldVal.Formula = NewVal
| > End If
| > Next OldVal
| > Abort:
| > End Sub
| >
| > This version includes a prompt for the currency conversion rate. If you don't want to apply the same conversion rate throughout
the
| > worksheet, you'll need to change 'ActiveSheet.UsedRange' to 'Selection' and select the range the macro is to apply to. The new
| > formula retains both the original value and the conversion rate.
| >
| > Cheers
| >
| > --
| > macropod
| > [MVP - Microsoft Word]
| >
| >
| > | No, did not modify. Tried again multiple times, the original still works fine
| > | though, and thinking about how I will be referencing each table individually
| > | when going back and forth from the destination webpage, I realize that
| > | rounding each table individually using your original formula is not a problem
| > | at all. Thanks Macropod.
| > |
| > | If you care to write one that can start from the very beginning in one step
| > | allowing for a bunch of text thrown into the tables, that would be great.
| > | Converting currencies and then rounding to the nearest nine.
| > |
| > | an example: I need to change $4699CAD into $3099Euro using the conversion
| > | rate of 0.66. A macro that could easily adapt to different currencies by
| > | throwing in the percentile would be great.
| > |
| > | Cheers
| > | M
| > |
| > |
| > |
| > | "macropod" wrote:
| > |
| > | > Hi mateo,
| > | >
| > | > It doesn't behave that way for me. On my system, it processes all cells containing only numeric values, or formulae that
return
| > | > numeric values, and skips any other cells (eg empty cells and cells with text). Merged cells have no effect - the code
processes
| > | > them just the same as it does with un-merged cells.
| > | >
| > | > Did you modify the code in any way?
| > | >
| > | > Cheers
| > | >
| > | > --
| > | > macropod
| > | > [MVP - Microsoft Word]
| > | >
| > | >
| > | > | Thanks for that Macropod, I should have mention the text titles. For some
| > | > | reason when running your new macro after selecting everything it either says
| > | > | "this macro requires merge cells to be of the same size." Or when just
| > | > | selecting numbers, it make each row contain the same number as the first cell
| > | > | in each row.
| > | > |
| > | > |
| > |
| >
| >
| >
 
Back
Top