changing all current cells to all uppercase and forcing all future entries to be in uppercase

kenton71

New Member
Joined
Jun 15, 2015
Messages
36
So, my boss LOVES uppercase. She wants everything in it. Now, I know how to change a cell or row, or column to uppercase, but how can I do it for a whole spreadsheet (thousands of rows, maybe 50 columns). Also, is there a way to then force any new entries into uppercase so I don't have to do this again?
 

Excel Facts

Format cells as currency
Select range and press Ctrl+Shift+4 to format cells as currency. (Shift 4 is the $ sign).
To force all entries to upper case insert the following:

Private Sub Worksheet_Change(ByVal Target As Range)
Application.EnableEvents = False
Target = UCase(Target)
Application.EnableEvents = True

End Sub
 
Upvote 0
For the initial run to get all caps in existing data. This would run from your standard code module 1.
Code:
Sub makeCaps()
Dim c As Range
Application.EnableEvents = False
For Each c In ActiveSheet.UsedRange
    If c.Text <> UCase(c.Text) Then c = UCase(c.Text)
Next
Application.EnableEvents = True
End Sub

then use the code from BadgerRoad to handle any future entries by putting that code in the Worksheet code module.

Or you can put this in the ThisWorkbook code module and cover all the sheets in a workbook.

Code:
Private Sub Workbook_SheetChange(ByVal Sh As Object, ByVal Target As Range)
 Application.EnableEvents = False
 Target = UCase(Target)
 Application.EnableEvents = True
End Sub

Caution, if you have existing Worksheet_Change or Workbook_SheetChange code you would need to merge the procedures since Excel will not allow two of the same type event procedures in a single code module.
 
Last edited:
Upvote 0
For the initial run to get all caps in existing data. This would run from your standard code module 1.
Code:
Sub makeCaps()
Dim c As Range
Application.EnableEvents = False
For Each c In ActiveSheet.UsedRange
    If c.Text <> UCase(c.Text) Then c = UCase(c.Text)
Next
Application.EnableEvents = True
End Sub
While the above code will work, this should be faster AND it processes each worksheet in the workbook as opposed to only doing the active sheet...
Code:
[table="width: 500"]
[tr]
	[td]Sub UpperCaseAllExistingTextOnEverySheet()
  Dim Ar As Range, Ws As Worksheet
  Application.ScreenUpdating = False
  For Each Ws In ThisWorkbook.Worksheets
    For Each Ar In Ws.Cells.SpecialCells(xlConstants, xlTextValues).Areas
      Ar = Evaluate(Replace("IF(@="""","""",UPPER(@))", "@", "'" & Ws.Name & "'!" & Ar.Address))
    Next
  Next
  Application.ScreenUpdating = True
End Sub[/td]
[/tr]
[/table]



Or you can put this in the ThisWorkbook code module and cover all the sheets in a workbook.
Code:
Private Sub Workbook_SheetChange(ByVal Sh As Object, ByVal Target As Range)
 Application.EnableEvents = False
 Target = UCase(Target)
 Application.EnableEvents = True
End Sub
Good idea about using the ThisWorkbok code module so that all sheets get upper cased with new entries; however, the code you posted will have problems if the user tries to paste multiple-celled or non-contiguous ranges into a sheet or if they attempt to clear an entire sheet. This code should be more robust...
Code:
[table="width: 500"]
[tr]
	[td]Private Sub Workbook_SheetChange(ByVal Sh As Object, ByVal Target As Range)
  Dim Ar As Range
  Application.EnableEvents = False
  On Error Resume Next
  For Each Ar In Intersect(Target, Sh.UsedRange).Areas
    Ar = Evaluate("IF(" & Ar.Address & "="""","""",UPPER(" & Ar.Address & "))")
  Next
  On Error GoTo 0
  Application.EnableEvents = True
End Sub[/td]
[/tr]
[/table]
 
Upvote 0

Forum statistics

Threads
1,213,543
Messages
6,114,245
Members
448,555
Latest member
RobertJones1986

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