Prompt for All Caps

singlgl1

Board Regular
Joined
Jan 13, 2007
Messages
127
I have a range of cells A1:A20 that has data validation and must be a double letter code contained in a list.The list is ALL Upper Case( must be Upper case to link correctly to another program).The problem I have is that some users will type the code in the cells rather than choose from the dropdown list, which results in an error when the other database imports it in.Is there an option in the validation that requires the user to actually use the dropdown list?As it is now the user can use the dropdown list or simply type in a code contained in the list whether upper case or not. Hope I'm making the issue clear enough to get help with this.Perhaps I could enter a Code that would prompt the user to use all Uppercase if it sees any lowercase letters in range A1:A20
I appreciate the help.
 

Excel Facts

Wildcard in VLOOKUP
Use =VLOOKUP("Apple*" to find apple, Apple, or applesauce
If this is put the the sheet's code module, any entry to a list validated cell will be forced into the same case as the source of the validation list.
Code:
Private Sub Worksheet_Change(ByVal Target As Excel.Range)
    Dim keyRange As Range, oneCell As Range
    Dim searchArray As Variant
    Application.EnableEvents = False
    On Error Resume Next
        With Target
            Set keyRange = Application.Intersect(.Cells, .SpecialCells(xlCellTypeAllValidation))
        End With
    On Error GoTo 0
    
    If Not keyRange Is Nothing Then
        For Each oneCell In keyRange
            With oneCell.Validation
                If .Type = xlValidateList Then
                    searchArray = Evaluate(.Formula1)
                    If TypeName(searchArray) <> "Error" Then
                        oneCell.Value = Application.Index(searchArray, Application.Match(oneCell.Value, searchArray, 0), 1)
                    End If
                End If
            End With
        Next oneCell
    End If
    Application.EnableEvents = True
End Sub
 
Upvote 0
Nice solution, Mike.

singlgl - As Mike has indicated, one solution is to use VBA to intercede on the user's behalf, i.e. the user can enter whatever will pass muster on the validation, including lowercase and then patch it for you by forcing uppercase (or case-matching against the validation list).

If deploying a VBA-based solution stumbles due to macro-security issues, you could explore the idea of using a help/hidden column that is just =Upper(A1) and push that column to your downstream app.
 
Upvote 0
singlgl1

I'm not trying for such a general solution as Mike. So just targeting your specifications, this is my suggestion. It is intended just to convert anything entered into A1:A20 into uppercase and your existing Data Validation can take care of whether or not it is in the allowed list.

<font face=Courier New><SPAN style="color:#00007F">Private</SPAN> <SPAN style="color:#00007F">Sub</SPAN> Worksheet_Change(<SPAN style="color:#00007F">ByVal</SPAN> Target <SPAN style="color:#00007F">As</SPAN> Range)<br>    <SPAN style="color:#00007F">Dim</SPAN> Changed <SPAN style="color:#00007F">As</SPAN> Range, c <SPAN style="color:#00007F">As</SPAN> Range, DVRange <SPAN style="color:#00007F">As</SPAN> Range<br><br>    <SPAN style="color:#00007F">Set</SPAN> DVRange = Range("A1:A20")<br>    <SPAN style="color:#00007F">Set</SPAN> Changed = Intersect(Target, DVRange)<br>    <SPAN style="color:#00007F">If</SPAN> <SPAN style="color:#00007F">Not</SPAN> Changed <SPAN style="color:#00007F">Is</SPAN> <SPAN style="color:#00007F">Nothing</SPAN> <SPAN style="color:#00007F">Then</SPAN><br>        Application.EnableEvents = <SPAN style="color:#00007F">False</SPAN><br>        <SPAN style="color:#00007F">For</SPAN> <SPAN style="color:#00007F">Each</SPAN> c <SPAN style="color:#00007F">In</SPAN> Changed<br>            c.Value = UCase(c.Value)<br>        <SPAN style="color:#00007F">Next</SPAN> c<br>        Application.EnableEvents = <SPAN style="color:#00007F">True</SPAN><br>    <SPAN style="color:#00007F">End</SPAN> <SPAN style="color:#00007F">If</SPAN><br><SPAN style="color:#00007F">End</SPAN> <SPAN style="color:#00007F">Sub</SPAN></FONT>



Mike
I had a problem with your code if I tried to delete one or more values from cells that contained Data Validation. It filled the cell(s) with #N/A values
 
Upvote 0

Forum statistics

Threads
1,215,054
Messages
6,122,895
Members
449,097
Latest member
dbomb1414

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