Written by Allen Wyatt (last updated February 9, 2023)
This tip applies to Excel 2007, 2010, 2013, 2016, 2019, and Excel in Microsoft 365
If you are just starting out developing macros, you may be looking for a simple way to offer a set of choices to a user, and then take an action based on the user's response. This is a relatively simple task, if you use the InputBox function along with a Select Case structure.
The first task is to set up your InputBox so it displays the information to the user. For example, let's say you have five options and you want the user to select one option from those five. You can use the following code to put together five options, each on their own line:
Prompt = "1. This is your first choice" & vbCrLf Prompt = Prompt & "2. This is your second choice" & vbCrLf Prompt = Prompt & "3. This is your third choice" & vbCrLf Prompt = Prompt & "4. This is your fourth choice" & vbCrLf Prompt = Prompt & "5. This is your fifth choice"
You can now use the Prompt string when you invoke the InputBox function in your macro. You then translate what the user responds with into a number that represents their choice from your five options. The code to do this is as follows:
UserResp = InputBox(Prompt, "The Big Question") UR = Val(UserResp)
In this example, the response from the InputBox function is assigned to the UserResp variable, which should be a string. The UR variable, which is a numeric, is then set based on the value of the string. (The Val function returns the value in a string.)
The only thing left to do is to take an action based on which number was chosen, 1 through 5. You can use the Select Case structure to do this. The full subroutine could appear as follows:
Sub Macro1() Dim Prompt As String Dim UserResp As String Dim UR As Single Prompt = "1. This is your first choice" & vbCrLf Prompt = Prompt & "2. This is your second choice" & vbCrLf Prompt = Prompt & "3. This is your third choice" & vbCrLf Prompt = Prompt & "4. This is your fourth choice" & vbCrLf Prompt = Prompt & "5. This is your fifth choice" UR = 0 While UR < 1 Or UR > 5 UserResp = InputBox(Prompt, "The Big Question") UR = Val(UserResp) Wend Select Case UR Case 1 'Do stuff for choice 1 here Case 2 'Do stuff for choice 2 here Case 3 'Do stuff for choice 3 here Case 4 'Do stuff for choice 4 here Case 5 'Do stuff for choice 5 here End Select End Sub
Notice that this example uses a While ... Wend loop around the InputBox function. This is done to make sure that the user enters a number between 1 and 5. If the value entered is outside that range, then the user is simply asked again.
Note:
ExcelTips is your source for cost-effective Microsoft Excel training. This tip (11059) applies to Microsoft Excel 2007, 2010, 2013, 2016, 2019, and Excel in Microsoft 365. You can find a version of this tip for the older menu interface of Excel here: Offering Options in a Macro.
Solve Real Business Problems Master business modeling and analysis techniques with Excel and transform data into bottom-line results. This hands-on, scenario-focused guide shows you how to use the latest Excel tools to integrate data from multiple tables. Check out Microsoft Excel 2013 Data Analysis and Business Modeling today!
Macros can allow you to do some fancy data validation in your workbooks, such as checking to see if the user entered ...
Discover MoreExcel allows you to define names that can refer either to ranges of cells or to constant information, such as formulas. ...
Discover MoreMacros are often used to process the data stored in a worksheet. Some of these processing needs can be pretty specific to ...
Discover MoreFREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
2023-02-10 09:55:14
J. Woolley
@Tomek, Brian
I often use vbNewLine: Chr(13) + Chr(10) or, on the Macintosh, Chr(13). Platform-specific new line character; whichever is appropriate for current platform.
2023-02-09 22:26:37
Tomek
@Brian:
Theoretically there are three VBA constants:
vbCr - carriage return = Chr(13)
vbLf - line feed =Chr(10)
vbCrLf - combination of the two above in that order.
Currently in Windows environment there is very little difference if you use any of them in your code, except, maybe, if you output to an external binary file. Historically, they were relevant to typewriters and early computer consoles.
If you use any with MsgBox in the prompt you will get the same result for each of them, and in MsgBox Title they are all ignored.
If you use them to add text to your document, whichever you use will be converted to the end-of paragraph mark (essentially equivalent to Chr(13).
From what I have seen most people would use vbCrLf.
It may be different on the Mac.
2023-02-09 13:08:55
Kiwerry
P.S. The appearance of the code on the site turned out to be as intended.
The hard-space character code only looks strange in the comment input box.
2023-02-09 12:38:07
Kiwerry
Thanks to Allen, and to Willy Vanhaelen for his comments. I built on these to make the interface slightly more user friendly by offering an explanation of what is required and showing what was entered. I also changed the Msgboxes to make them transient. The following code worked as expected on my W10/MS 365 machine, but comes with no guarantees...
Note: The code contains hard spaces in an attempt to preserve the indentation. If the nbsp; strings (including the preceding&) are copied into your VBA module unchanged, simply replace them all with ordinary space characters.
'============================================================================================================
Private Sub User_Choice_Example2()
'https://excelribbon.tips.net/T011059_Offering_Options_in_a_Macro.html _
Comment on 2019-01-20 13:45:08 by Willy Vanhaelen _
Amended CvZ
'============================================================================================================
Dim WshShell
Set WshShell = CreateObject("WScript.Shell")
Dim BtnCode, The_Text, Delay_Secs, The_Title, The_Type
Dim Prompt As String
Dim UserResp As String
' Get user choice
Prompt = _
"1. This is your first choice" & vbCrLf & _
"2. This is your second choice" & vbCrLf & _
"3. This is your third choice" & vbCrLf & _
"4. This is your fourth choice" & vbCrLf & _
"5. This is your fifth choice"
Do
UserResp = InputBox(Prompt, "The Big Question")
Select Case UserResp
Case ""
MsgBox "Exiting at your request"
Exit Sub
Case "1", "2", "3", "4", "5"
Exit Do
Case Else
MsgBox "Valid responses are 1 or 2 or 3 or 4 or 5" _
& vbCrLf & "You entered: " & UserResp
End Select
Loop Until InStr("1×2×3×4×5×", UserResp & "×") '0 if not found
' Use user choice
Delay_Secs = 2
The_Text = "You chose "
The_Title = "Transient box, self-destruct in " & Delay_Secs & " seconds."
The_Type = 64
Select Case UserResp
Case "1"
'replace with your code
WshShell.Popup The_Text & "Choice 1", Delay_Secs, The_Title, The_Type
Case "2"
'replace with your code
WshShell.Popup The_Text & "Choice 2", Delay_Secs, The_Title, The_Type
Case "3"
'replace with your code
WshShell.Popup The_Text & "Choice 3", Delay_Secs, The_Title, The_Type
Case "4"
'replace with your code
WshShell.Popup The_Text & "Choice 4", Delay_Secs, The_Title, The_Type
Case "5"
'replace with your code
WshShell.Popup The_Text & "Choice 5", Delay_Secs, The_Title, The_Type
End Select
Set WshShell = Nothing
End Sub
2023-02-09 06:51:05
Brian
Is vbCrLf preferred to vbCrLf? Is there any difference? I suppose for that matter Chr(10)?
2019-01-21 13:02:10
Preston
Thanks for this tip, Mr. Wyatt! Never thought to use the InputBox that way--simple but elegant. Nice.
2019-01-20 13:45:08
Willy Vanhaelen
The While ... Wend loop used in this tip's macro is obsolete and is still maintained in vba only for backward compatibility. It is better coding practice now to use Do ... Loop.
The While ... Wend loop in this macro has also 2 flaws.
1) The InputBox has an OK and Cancel button but if you click the Cancel button, the input box is displayed again. So if the user changes its mind or realizes he runs the macro by mistake, he has no possibility to quit the macro.
2) If you enter i.e. 2.2 or a letter the macro should display the input box again because it is an illegal entry but instead it doesn't do anything and stops.
Here is my (slightly simplified) version that deals with these flaws:
Sub Macro1()
Dim Prompt As String
Dim UserResp As String
Prompt = _
"1. This is your first choice" & vbCrLf & _
"2. This is your second choice" & vbCrLf & _
"3. This is your third choice" & vbCrLf & _
"4. This is your fourth choice" & vbCrLf & _
"5. This is your fifth choice"
Do
UserResp = InputBox(Prompt, "The Big Question")
If UserResp = "" Then Exit Sub
Loop Until InStr("1×2×3×4×5×", UserResp & "×")
Select Case UserResp
Case "1"
MsgBox "choice 1" 'replace with your code
Case "2"
MsgBox "choice 2" 'replace with your code
Case "3"
MsgBox "choice 3" 'replace with your code
Case "4"
MsgBox "choice 4" 'replace with your code
Case "5"
MsgBox "choice 5" 'replace with your code
End Select
End Sub
Got a version of Excel that uses the ribbon interface (Excel 2007 or later)? This site is for you! If you use an earlier version of Excel, visit our ExcelTips site focusing on the menu interface.
FREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
Copyright © 2023 Sharon Parq Associates, Inc.
Comments