when to use () and when not in vba functions

lezawang

Well-known Member
Joined
Mar 27, 2016
Messages
1,805
Office Version
  1. 2016
Platform
  1. Windows
Hi
I am reading a article about when I should user ( ) and when not. I wrote a code below but not sure why Y =1

Code:
Sub myfoo()
    Dim x As Integer
    Dim y As Integer
    x = InputBox("enter number")
    y = MsgBox(2 * x)
    MsgBox y
End Sub

Also, do you know where I can read about this topic, when I call a function without () and when I need (). This article https://docs.microsoft.com/en-us/of...g-started/calling-sub-and-function-procedures
is good but I need to read more and simpler methods to understand. Thank you very much
 

Excel Facts

Why are there 1,048,576 rows in Excel?
The Excel team increased the size of the grid in 2007. There are 2^20 rows and 2^14 columns for a total of 17 billion cells.
Run this code and you will understand why the 2nd message box returns 1
- it is NOTHING to do with "y"
- it is dependant on what you clicked to close the message box (try abort, retry and ignore)
Code:
Sub Test1()
    Dim y
    y = MsgBox("text", vbAbortRetryIgnore)
    MsgBox y
End Sub

This is the same as above
Code:
Sub Test2()
    MsgBox MsgBox("text", vbAbortRetryIgnore)
End Sub


Is this what you want?

Code:
Sub myfoo()
    Dim x As Integer
    Dim y As Integer
    x = InputBox("enter number")
    y = 2 * x
    MsgBox y
End Sub
 
Last edited:
Upvote 0
When you invoke a Sub with Call, you must use parens around the arguments:

Code:
Call MySub(arg1, arg2)

When you assign the result of a function to a variable, you must use parens around the arguments:

Code:
myResult = MyFunc(arg1, arg2)

If you are not using Call, and want to pass arguments ByVal (by value, a copy of the variable) or ByRef (by reference, a pointer to the variable), according to the procedure's signature, you don't include parens:

Code:
MySub arg1, arg2
MyFunc arg1, arg2

If you want to pass arguments ByVal, irrespective of the procedure’s signature (which won't work for a procedure expecting an array (because arrays are always passed by reference) or an object), you enclose the argument in parens, or an extra set of parens. In the examples below, arg1 is passed by value, and arg2 according to the procedure’s signature:

Code:
Call MySub((arg1), arg2)
myResult = MyFunc((arg1), arg2)
MySub (arg1), arg2
MyFunc (arg1), arg2

That’s because when you add parens around an argument that doesn't require them, the argument is evaluated …

StringExpression -> String
NumericExpression -> Number
Range -> Variant for single cell, 2D Variant array for multi-cell
Object other than Range -> Error

…, and the result of the evaluation is passed to the procedure. It means the argument is passed by value regardless of how the procedure requested it.

That also explains why you can't use parens around two or more arguments when they are not required; the evaluation of (arg1) may be meaningful, but the evaluation of (arg1, arg2) is not. That's why this generates an error:

Code:
Msgbox (Prompt:=arg1, Title:=arg2, Buttons:=arg3)

That also explains why if you call a procedure expecting a range with parens where none are required, you get a type mismatch error; because the evaluation of a range is a Variant, or Variant/Array.

You can't pass a Variant ByRef as a static type (Long, String, ...).

You can pass a statically-typed variable ByRef as a Variant, and the called procedure can modify its value with data of the appropriate (or coercible) type.

So: Parens means completely different things according to context. VBA might have used some other bookends (curly braces, square brackets, whatever) to indicate enclosing a list of arguments versus a call for evaluation, but it didn't.

Since objects other than Range object are always passed ByRef, you can never put unnecessary parens around an object variable. Chip Pearson (http://www.cpearson.com/excel/byrefbyval.aspx) explains the meaning of ByRef and ByVal for an object variable:

The ByRef and ByVal modifiers indicate how the reference is passed to the called procedure. When you pass an object type variable to a procedure, the reference or address to the object is passed -- you never really pass the object itself. When you pass an object ByRef, the reference is passed by reference and the called procedure can change the object to which that reference refers to. When an object is passed ByVal, a copy of the reference (address) of the object is passed.
 
Upvote 0
This is very great. Thank you so much. I will read it carefully. Thanks a lot all.
 
Upvote 0

Forum statistics

Threads
1,224,820
Messages
6,181,159
Members
453,021
Latest member
Justyna P

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