Column All Upper Case

M

Michael Koerner

Is there a way to set up say Col F to be all upper case when I type in it. I
would just like to continue to enter data and not have to think that I am
entering a Canadian Postal Code and manually change the text to upper case.
TIA
 
R

Rick Rothstein

Right click the tab at the bottom of the worksheet where you want this
functionality, select View Code from the pop up menu that appears, and then
copy/paste the following into the code window that appeared...

Private Sub Worksheet_Change(ByVal Target As Range)
If Target.Column = 6 Then
Application.EnableEvents = False
Target.Formula = UCase(Target.Formula)
Application.EnableEvents = True
End If
End Sub

Now, go back to your worksheet and type something into Column F in lower
case and watch it change to upper case.
 
M

Michael Koerner

Rick;

Absolutely fantastic, that is two in a row you have provided with great
success. Thank you very much.

I do have one question. Would it be possible to change the "If
Target.Column = 6 Then" to read (going out on a limb here) If Target.Column
= 5 or If Target Column=6 Then.... I would like to include column 5 which
contains prov/state

--

Regards
Michael Koerner


Right click the tab at the bottom of the worksheet where you want this
functionality, select View Code from the pop up menu that appears, and then
copy/paste the following into the code window that appeared...

Private Sub Worksheet_Change(ByVal Target As Range)
If Target.Column = 6 Then
Application.EnableEvents = False
Target.Formula = UCase(Target.Formula)
Application.EnableEvents = True
End If
End Sub

Now, go back to your worksheet and type something into Column F in lower
case and watch it change to upper case.
 
R

Rick Rothstein

Yes, you can do that. Here is the statement...

If Target.Column = 5 Or Target.Column = 6 Then
 
M

Michael Koerner

Thanks very much, greatly appreciated.

--

Regards
Michael Koerner


Yes, you can do that. Here is the statement...

If Target.Column = 5 Or Target.Column = 6 Then
 
G

Gord Dibben

Canadian postal codes like a space between 3rd and 4th character.

Private Sub Worksheet_Change(ByVal Target As Excel.Range)
If Target.Column <> 7 Then Exit Sub 'adjust column to suit
On Error GoTo ErrHandler
Application.EnableEvents = False
With Target
.Formula = UCase(Target.Formula)
.Value = (Left(Target.Value, 3) & " " & Right(Target.Value, 3))
End With
ErrHandler:
Application.EnableEvents = True
End Sub


Gord Dibben MS Excel MVP
 
M

Michael Koerner

Coming from Ottawa I automatically put in the space <g>

--

Regards
Michael Koerner


"Gord Dibben" <gorddibbATshawDOTca> wrote in message
Canadian postal codes like a space between 3rd and 4th character.

Private Sub Worksheet_Change(ByVal Target As Excel.Range)
If Target.Column <> 7 Then Exit Sub 'adjust column to suit
On Error GoTo ErrHandler
Application.EnableEvents = False
With Target
.Formula = UCase(Target.Formula)
.Value = (Left(Target.Value, 3) & " " & Right(Target.Value, 3))
End With
ErrHandler:
Application.EnableEvents = True
End Sub


Gord Dibben MS Excel MVP
 
G

Gord Dibben

Coming from a small town in B.C. I do the same when hand entering on an
envelope.

When entering in a worksheet I just let the event code do it all.


Gord
 
M

Michael Koerner

After a good nights sleep, your suggestion really made a lot of sense. thank
you very much.

But, when I tried to insert the macro you provided, I received a compile
error indicating I had an ambiguous statement.

I also have a couple of questions. The column with the postal code is column
6. Your macro I believe indicated <>7 I would also like to have column 5 if
possible in Upper Case as this is the prov/state column.

--

Regards
Michael Koerner


"Gord Dibben" <gorddibbATshawDOTca> wrote in message
Coming from a small town in B.C. I do the same when hand entering on an
envelope.

When entering in a worksheet I just let the event code do it all.


Gord
 
G

Gord Dibben

A worksheet cannot have multiple events of the same type.

Different types...........yes.........same type........no.

Sounds like you have more than one worksheet_change event in that sheet
module.

Either combine or change one of them to a different type.

BTW...............postal codes are in column 6...........is column 5 simply
province names?

I can't imagine you want the same format on both columns in that case.

Assumes you enter a province name in column 5 then a postal code in column 6

After the column 6 entry the code will run on both columns.

Private Sub Worksheet_Change(ByVal Target As Excel.Range)
If Intersect(Range(Target(1).Address), _
Range("F:F")) Is Nothing Then Exit Sub
On Error GoTo ErrHandler
Application.EnableEvents = False
With Target
.Formula = UCase(Target.Formula)
.Value = (Left(Target.Value, 3) & " " & Right(Target.Value, 3))
End With
With Target.Offset(0, -1)
.Formula = UCase(.Formula)
End With
ErrHandler:
Application.EnableEvents = True
End Sub


Gord
 
M

Michael Koerner

Gord;

Absolutely correct, I did just want the Prov in upper case. Works like a
charm until I enter a US zip code. But, that is not a problem, I have fewer
of those and it is easy to delete a character. Thank you very much

--

Regards
Michael Koerner


"Gord Dibben" <gorddibbATshawDOTca> wrote in message
A worksheet cannot have multiple events of the same type.

Different types...........yes.........same type........no.

Sounds like you have more than one worksheet_change event in that sheet
module.

Either combine or change one of them to a different type.

BTW...............postal codes are in column 6...........is column 5 simply
province names?

I can't imagine you want the same format on both columns in that case.

Assumes you enter a province name in column 5 then a postal code in column 6

After the column 6 entry the code will run on both columns.

Private Sub Worksheet_Change(ByVal Target As Excel.Range)
If Intersect(Range(Target(1).Address), _
Range("F:F")) Is Nothing Then Exit Sub
On Error GoTo ErrHandler
Application.EnableEvents = False
With Target
.Formula = UCase(Target.Formula)
.Value = (Left(Target.Value, 3) & " " & Right(Target.Value, 3))
End With
With Target.Offset(0, -1)
.Formula = UCase(.Formula)
End With
ErrHandler:
Application.EnableEvents = True
End Sub


Gord
 
R

Rick Rothstein

Why not let the code handle that for you too? You can enter your Canadian
postal codes with or without the space and you can enter any 9-digit US Zip
Codes (assuming you use those) with or without the dash between the first 5
digits and the last 4 digits...

Private Sub Worksheet_Change(ByVal Target As Excel.Range)
Dim Temp As String
If Intersect(Range(Target(1).Address), _
Range("F:F")) Is Nothing Then Exit Sub
On Error GoTo ErrHandler
Application.EnableEvents = False
With Target
If Not .HasFormula Then
Temp = Replace(UCase(Target.Value), " ", "")
If Len(Temp) = 6 Then
.Value = Format(Temp, "@@@ @@@")
ElseIf Len(Temp) = 9 Then
.Value = Format(Temp, "@@@@@-@@@@")
End If
End If
End With
With Target.Offset(0, -1)
.Formula = UCase(.Formula)
End With
ErrHandler:
Application.EnableEvents = True
End Sub
 
R

Rick Rothstein

.Formula = UCase(Target.Formula)
.Value = (Left(Target.Value, 3) & " " & Right(Target.Value, 3))

In your above two consecutive lines of code, there is no real need to
protect the value by using the Formula property (of course it doesn't hurt
either) when any formula that might be in the cell will be overwritten by
your second line of code. While I'm guessing the OP doesn't actually have
any formulas in his cells in this column, I still added a protection in the
modification of your code that I posted (to handle US Zip Codes as well as
Canadian Postal Codes) for formulas via a test of the HasFormula property.
 
M

Michael Koerner

I'm all for that, and thank you all for all the help. It is greatly
appreciated.

--

Regards
Michael Koerner


Why not let the code handle that for you too? You can enter your Canadian
postal codes with or without the space and you can enter any 9-digit US Zip
Codes (assuming you use those) with or without the dash between the first 5
digits and the last 4 digits...

Private Sub Worksheet_Change(ByVal Target As Excel.Range)
Dim Temp As String
If Intersect(Range(Target(1).Address), _
Range("F:F")) Is Nothing Then Exit Sub
On Error GoTo ErrHandler
Application.EnableEvents = False
With Target
If Not .HasFormula Then
Temp = Replace(UCase(Target.Value), " ", "")
If Len(Temp) = 6 Then
.Value = Format(Temp, "@@@ @@@")
ElseIf Len(Temp) = 9 Then
.Value = Format(Temp, "@@@@@-@@@@")
End If
End If
End With
With Target.Offset(0, -1)
.Formula = UCase(.Formula)
End With
ErrHandler:
Application.EnableEvents = True
End Sub
 
G

Gord Dibben

Thanks Rick


Gord

In your above two consecutive lines of code, there is no real need to
protect the value by using the Formula property (of course it doesn't hurt
either) when any formula that might be in the cell will be overwritten by
your second line of code. While I'm guessing the OP doesn't actually have
any formulas in his cells in this column, I still added a protection in the
modification of your code that I posted (to handle US Zip Codes as well as
Canadian Postal Codes) for formulas via a test of the HasFormula property.
 

Ask a Question

Want to reply to this thread or ask your own question?

You'll need to choose a username for the site, which only take a couple of moments. After that, you can post your question and our members will help you out.

Ask a Question

Similar Threads


Top