As you may, or may not know, there are multiple types we can use. The code below will show you some of these types. We will kick off we the most common use of an INPUTBOX, collect text:
Sub StandardInputBox()
Dim strName As String
'InputBox(prompt[, title] [, default] [, xpos] [, ypos] [, helpfile, context])
strName = InputBox("Enter you name.", "NAME COLLECTOR")
'Exit sub if Cancel button used or no text entered
If strName = vbNullString Then Exit Sub
MsgBox "Hello " & strName
End Sub
Now we can look at how we can use Application.InputBox with different types.
| Type | Meaning |
|---|---|
| 0 | A formula |
| 1 | A number |
| 2 | Text (a string) |
| 4 | A logical value (True or False) |
| 8 | A cell reference, as a Range object |
| 16 | An error value, such as #N/A |
| 64 | An array of values |
Sub NumbersOnly()
Dim dNum As Long
'expression.InputBox(Prompt, Title, Default, Left, Top, HelpFile, HelpContextID, Type)
dNum = Application.InputBox("Enter you age.", "AGE COLLECTOR", , , , , , 1)
'Exit sub if Cancel button used
If dNum = 0 Then Exit Sub
'As we have used Type 1 Inputbox, Excel will handle any text entered
MsgBox "You are " & dNum & " Years old."
End Sub
Sub RangeAsObject()
Dim rRange As Range
Dim lReply As Long
'We use On Error so we ignore run time errors
On Error Resume Next
'expression.InputBox(Prompt, Title, Default, Left, Top, HelpFile, HelpContextID, Type)
Set rRange = Application.InputBox("With you mouse, select a range of cells.", _
"RANGE COLLECTOR", , , , , , 8)
On Error GoTo 0
'Check if range is valid
If rRange Is Nothing Then
'If range not valid, ask if they wish to retry
rRange = MsgBox("Non valid range. Try again?", vbOKCancel + vbQuestion)
If rRange = vbCancel Then 'No retry
Exit Sub
Else 'retry
Run "RangeAsObject"
End If
Else
MsgBox rRange.Address
End If
End Sub
Now let's see how we can the INPUTBOX to evaluate a chosen range with an expression collected from a user.
Sub CollectExpressions()
Dim strExpression As String
Dim rRange As Range
On Error Resume Next
Set rRange = Application.InputBox("With you mouse, select a range of cells to evaluate.", _
"RANGE COLLECTOR", , , , , , 8)
On Error GoTo 0
If rRange Is Nothing Then
rRange = MsgBox("Non valid range. Try again?", vbOKCancel + vbQuestion)
If rRange = vbCancel Then 'No retry
Exit Sub
Else 'retry
Run "CollectExpressions"
End If
End If
strExpression = InputBox("Enter you expession.E.g. >5 or <10", "EXPRESSION COLLECTOR")
If strExpression = vbNullString Then Exit Sub
MsgBox "Using your expression." & vbNewLine _
& "COUNTIF = " & WorksheetFunction.CountIf(rRange, strExpression) & vbNewLine _
& "Top left cell = " & Evaluate(rRange(1, 1) & strExpression) & vbNewLine
End Sub
Hopefully, you find some uses for different INPUTBOX types.
See also:
See also Index to Excel VBA Code and Index to Excel Freebies and Lesson 1 - Excel Fundamentals and Index to how to… providing a range of solutions.
Microsoft ® and Microsoft Excel ® are registered trademarks of Microsoft Corporation. OzGrid is in no way associated with Microsoft
Click here to visit our Free 24/7 Excel/VBA Help Forum where there are thousands of posts you can get information from, or you can join the Forum and post your own questions.