Macro to Convert all the data in column in Negative Value

Chandresh

Board Regular
Joined
Jul 21, 2009
Messages
146
HI All ,

I have written below code for converting all the numbers in the column to negative value however if some text comes in between my macro is not running can any one help me also the macro should run in all the sheets in that workbook.


Sub Cnegative()
'
' Cnegative Macro
'
For Each cell In Range("e3:e5000")
If cell.Value > 0 Then
cell.Value = cell.Value * -1
End If
Next cell
End Sub
 

Excel Facts

Remove leading & trailing spaces
Save as CSV to remove all leading and trailing spaces. It is faster than using TRIM().
You can add to your if statement the following to get it to ignore non-numerical data like text:
Code:
If cell.Value > 0 And IsNumeric(cell.Value) Then

To get it to run through each sheet in the workbook, you can enclose your code in another for loop like so:

Code:
For i = 1 to ActiveWorkbook.Sheets.Count
    For Each cell in ActiveWorkboook.Sheets(i).Range("E3:E5000")
.
.
.
    Next cell
Next i
 
Upvote 0
Perhaps
Code:
 If cell.Value < 999999999 And cell.Value > 0 Then

or
Code:
If IsNumeric(cell.Value) And cell.Value > 0 Then
 
Last edited:
Upvote 0
or using SpecialCells property
Code:
Sub Cnegative3()
    On Error Resume Next
    For Each cell In Range("e3:e5000").SpecialCells(xlCellTypeConstants, xlNumbers)
        If Icell.Value > 0 Then cell.Value = -cell.Value
    Next cell
End Sub
 
Last edited:
Upvote 0
perhaps simplest of all...

Code:
Sub Cnegative()
    For Each cell In Range("e3:e5000")
    On Error Resume Next
       If cell.Value > 0 Then cell.Value = -cell.Value
    Next cell
    On Error GoTo 0
End Sub
 
Upvote 0
hi its working fine thanks for your help ...however how to loop this for all sheets in this workbook.
 
Upvote 0
Like this:
Code:
Sub Cnegative()
Dim ws As Worksheet, cell as Range
For Each ws In ThisWorkbook.Worksheets
    For Each cell In ws.Range("e3:e5000")
        On Error Resume Next
           If cell.Value > 0 Then cell.Value = -cell.Value
        Next cell
    On Error GoTo 0
Next ws
End Sub
 
Last edited:
Upvote 0
HI Cold you please help me looping below macro in all the worksheet ... am confused looping the same

Sub Loopforall()

On Error Resume Next
For Each cell In Range("C3:C250000,E3:E250000,Q3:Q250000,S3:s250000").SpecialCells(xlCellTypeConstants, xlNumbers)
If Icell.Value > 0 Then cell.Value = -cell.Value
Next cell

Range("G26658,C:C,E:E,Q:Q,S:S").Select
Range("S26636").Activate
Selection.NumberFormat = "0"
Selection.NumberFormat = "0.00"
Range("A1").Activate
End Sub
 
Upvote 0
Using code tags around your code mnakes it easier to read (to do this next time: click on # icon above post and paste your code inside the code tags)

Try this
Code:
For Each cell In Union(Range("C3:C250000"), Range("E3:E250000"), Range("Q3:Q250000"), Range("S3:s250000")).SpecialCells(xlCellTypeConstants, xlNumbers)
    If cell.Value > 0 Then cell.Value = -cell.Value
Next cell
 
Last edited:
Upvote 0

Forum statistics

Threads
1,214,827
Messages
6,121,818
Members
449,049
Latest member
cybersurfer5000

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