Optional arguments in function

MetLife

Active Member
Joined
Jul 2, 2012
Messages
330
Office Version
  1. 365
Hi,

I have a function with optional inputs. The thing is I need some way of knowing was an input entered or not. How do I do this?

Function Read(i1 As Integer, Optional i2 As Integer, Optional i3 As Integer, Optional i4 As Integer)

How do I tell if "i4" was entered or not?

Thanks
 

Excel Facts

When did Power Query debut in Excel?
Although it was an add-in in Excel 2010 & Excel 2013, Power Query became a part of Excel in 2016, in Data, Get & Transform Data.
There are two ways I can think of:

Option 1:
You can declare optional parameters of any data type and provide a default value to be used if that parameter is omitted.

Code:
'Option 1
Function Read(i1 As Integer, Optional i2 As Integer = 9999, Optional i3 As Variant = 9999, Optional i4 As Variant = 9999)
    
    If i2 = 9999 Then
        MsgBox "Parameter i2 not passed"
    End If
    
    If i3 = 9999 Then
        MsgBox "Parameter i3 not passed"
    End If
    
    If i4 = 9999 Then
        MsgBox "parameter i4 not passed"
    End If
    
End Function

Option 2:
If you change the datatype of the Optional variables to Variant then you can use the IsMissing function to determine if the parameter was passed. It will return false for any other datatype, even if that parameter is declared as optional and is in fact missing. It also won't work if you assign a default value to the Optional Variant variable.

Code:
'Option 2
Function Read(i1 As Integer, Optional i2 As Variant, Optional i3 As Variant, Optional i4 As Variant)
    
    If IsMissing(i2) Then
        MsgBox "Parameter i2 not passed"
    End If
    
    If IsMissing(i3) Then
        MsgBox "Parameter i3 not passed"
    End If
    
    If IsMissing(i4) Then
        MsgBox "parameter i4 not passed"
    End If
    
End Function
 
Upvote 0
There are two ways I can think of:

Option 1:
You can declare optional parameters of any data type and provide a default value to be used if that parameter is omitted.

Code:
'Option 1
Function Read(i1 As Integer, Optional i2 As Integer = 9999, Optional i3 As Variant = 9999, Optional i4 As Variant = 9999)
    
    If i2 = 9999 Then
        MsgBox "Parameter i2 not passed"
    End If
    
    If i3 = 9999 Then
        MsgBox "Parameter i3 not passed"
    End If
    
    If i4 = 9999 Then
        MsgBox "parameter i4 not passed"
    End If
    
End Function

Option 2:
If you change the datatype of the Optional variables to Variant then you can use the IsMissing function to determine if the parameter was passed. It will return false for any other datatype, even if that parameter is declared as optional and is in fact missing. It also won't work if you assign a default value to the Optional Variant variable.

Code:
'Option 2
Function Read(i1 As Integer, Optional i2 As Variant, Optional i3 As Variant, Optional i4 As Variant)
    
    If IsMissing(i2) Then
        MsgBox "Parameter i2 not passed"
    End If
    
    If IsMissing(i3) Then
        MsgBox "Parameter i3 not passed"
    End If
    
    If IsMissing(i4) Then
        MsgBox "parameter i4 not passed"
    End If
    
End Function

Sorry, forgot to change the i3 and i4 variable datatypes to integer. Here is the correct code for Option 1:

Code:
'Option 1
Function Read(i1 As Integer, Optional i2 As Integer = 9999, Optional i3 As Integer = 9999, Optional i4 As Integer = 9999)
    
    If i2 = 9999 Then
        MsgBox "Parameter i2 not passed"
    End If
    
    If i3 = 9999 Then
        MsgBox "Parameter i3 not passed"
    End If
    
    If i4 = 9999 Then
        MsgBox "parameter i4 not passed"
    End If
    
End Function
 
Upvote 0

Forum statistics

Threads
1,223,907
Messages
6,175,301
Members
452,633
Latest member
DougMo

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