Array Formula problem in VBA

iggydarsa

Well-known Member
Joined
Jun 28, 2005
Messages
1,780
Office Version
  1. 2019
Platform
  1. Windows
Hi all

When I enter the following formula manually (with Ctrl+Shift+Enter) it works fine:
=INDEX(tbl_List[Referral Name], MAX((tbl_List[Intake Rep]=B2)*(tbl_List[Clean Doc Count]=MAX(IF(tbl_List[Intake Rep]=B2, IF(tbl_List[Clean Doc %]=MIN(IF(tbl_List[Intake Rep]=B2, tbl_List[Clean Doc %])), tbl_List[Clean Doc Count]))))*(tbl_List[Clean Doc %]=MIN(IF(tbl_Intake[Intake Rep]=B2, tbl_List[Clean Doc %])))*(ROW(tbl_List[Referral Name]))))

but when I use it in VBA like this:
shSand.Range("C2").FormulaArray = "=INDEX(tbl_List[Referral Name], MAX((tbl_List[Intake Rep]=B2)*(tbl_List[Clean Doc Count]=MAX(IF(tbl_List[Intake Rep]=B2, IF(tbl_List[Clean Doc %]=MIN(IF(tbl_List[Intake Rep]=B2, tbl_List[Clean Doc %])), tbl_List[Clean Doc Count]))))*(tbl_List[Clean Doc %]=MIN(IF(tbl_Intake[Intake Rep]=B2, tbl_List[Clean Doc %])))*(ROW(tbl_List[Referral Name]))))"

I get the following error:
Unable to set the FormulaArray property of the Range class

What am i doing wrong?
 
  • Like
Reactions: ZVI

Excel Facts

Copy formula down without changing references
If you have =SUM(F2:F49) in F50; type Alt+' in F51 to copy =SUM(F2:F49) to F51, leaving the formula in edit mode. Change SUM to COUNT.
The FormulaArray property has a limit of 255 characters, which your formula exceeds. Hence the error. As a workaround, you can enter your formula with placeholders for parts of your formula, and then replace them with the actual text for your formula. Here's an example...

Code:
    Dim formulaPart1 As String
    formulaPart1 = "tbl_List[Intake Rep]=B2"
    
    Dim formulaPart2 As String
    formulaPart2 = "tbl_List[Clean Doc Count]=MAX(IF(tbl_List[Intake Rep]=B2, IF(tbl_List[Clean Doc %]=MIN(IF(tbl_List[Intake Rep]=B2, tbl_List[Clean Doc %])), tbl_List[Clean Doc Count])))"


    Dim formulaPart3 As String
    formulaPart3 = "tbl_List[Clean Doc %]=MIN(IF(tbl_List[Intake Rep]=B2, tbl_List[Clean Doc %]))"


    With shSand.Range("C2")
        .FormulaArray = "=INDEX(tbl_List[Referral Name], MAX((X_X_X)*(Y_Y_Y)*(Z_Z_Z)*(ROW(tbl_List[Referral Name]))))"
        .Replace "X_X_X", formulaPart1
        .Replace "Y_Y_Y", formulaPart2
        .Replace "Z_Z_Z", formulaPart3
    End With

By the way, I assumed that your meant "tbl_List", not "tbl_Intake", in part of your formula.

Hope this helps!
 
Upvote 0
By the way, I assumed that your meant "tbl_List", not "tbl_Intake", in part of your formula.

First of all, how did you even catch that? I am flabbergasted.
And secondly, your code worked like charm.

Previously I saw your other posts on this subject and tried to do it but failed to parse it correctly and kept getting errors.

Thank you again.
 
Upvote 0

Forum statistics

Threads
1,214,983
Messages
6,122,588
Members
449,089
Latest member
Motoracer88

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