VBA array with array formulae

tiredofit

Well-known Member
Joined
Apr 11, 2013
Messages
1,825
Office Version
  1. 365
  2. 2019
Platform
  1. Windows
In excel, this is perfectly valid:

Rich (BB code):
=MATCH(1,F1=C1:C100)*(G1=D1:D100),0)

when entered as an ARRAY formula, using Ctrl+Shift+Enter.

Is it possible to use a similar syntax in VBA arrays?

For example:

Rich (BB code):
Dim FirstRng As Range
Set FirstRng=Range("C1:C100")

Dim SecondRng As Range
Set SecondRng=Range("D1:D100")

OutputArray(Counter, 1) = Application.WorksheetFunction.Match(1, (StartArray(Counter, 6) = FirstRng) * (StartArray(Counter, 7) = SecondRng), 0 )



I am getting a Type mismatch error.

Thanks


 
Last edited:

Excel Facts

Fastest way to copy a worksheet?
Hold down the Ctrl key while dragging tab for Sheet1 to the right. Excel will make a copy of the worksheet.
Hi,

You can test following

Code:
MsgBox Evaluate("=MATCH(1,F1=C1:C100)*(G1=D1:D100),0)")

Hope this will help
 
Upvote 0
Type mismatch would incicate an incorrect data type rather than an error in the syntax, possibly one of the array variables not declared correctly?

Personally, I would try using the Application.Evaluate method, which should work as an array.
Code:
OutputArray(Counter, 1) = [Match(1, (StartArray(Counter, 6) = FirstRng) * (StartArray(Counter, 7) = SecondRng), 0 )]
or an alternative
Code:
OutputArray(Counter, 1) = [AGGREGATE(15,6,ROW(FirstRng) / (StartArray(Counter, 6) = FirstRng) / (StartArray(Counter, 7) = SecondRng), 1)]
I think that the syntax is correct.
 
Upvote 0
Thanks for the suggestions.

This worked:

Rich (BB code):
OutputArray(Counter, 1) = [Match(1, (StartArray(Counter, 6) = FirstRng) * (StartArray(Counter, 7) = SecondRng), 0 )]


What is the significance of using square brackets?

Seems to NOT work without them.





 
Last edited:
Upvote 0
James, see post 5.

Square brackets are a simplified version of evaluate.
 
Upvote 0

Forum statistics

Threads
1,213,531
Messages
6,114,167
Members
448,554
Latest member
Gleisner2

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