Please could someone help to get this array working in a table using VB, I get an error and stuck

Dave01

Board Regular
Joined
Nov 30, 2018
Messages
116
Office Version
  1. 2019
  2. 2016
Platform
  1. Windows
Range("P1").Value = "Assigned To"
Range("p2").Select
Selection.FormulaArray = _
"=IFERROR(INDEX('Parked Consolidated'!C[-8],MATCH(1,([@[Company Code]]='Parked Consolidated'!C[-15])*([@Vendor]='Parked Consolidated'!C[-13])*([@[Document Number]]='Parked Consolidated'!C[-11])*([@[Posting Date]]='Parked Consolidated'!C[-9]),0)),""Not Assigned"")"


I get the error

Unable to set the FormulaArray property of the range Class.

Im not sure what this means, maybe an issue with the range in the table ? Im not sure how to fix it.

thanks in advanced.

David.
 

Excel Facts

Can a formula spear through sheets?
Use =SUM(January:December!E7) to sum E7 on all of the sheets from January through December
FormulaArray has a limit of 255 characters, which you are exceeding. The simplest option would be to shorten the sheet name.
 
Upvote 0
Is this just a VB thing ? because if I do it manually, and press ctrl + shift and return it works
 
Upvote 0
I found this, I;m trying to adapt it, maybe a work around, I have about 8 of them to do for 8 columns.

”’ If the long formula can be broken into parts, where the second part can
”’ be replaced by a dummy function, this approach can be used…
Public Sub LongArrayFormula()
Dim theFormulaPart1 As String
Dim theFormulaPart2 As String
theFormulaPart1 = “=IF(MONTH(DATE(YEAR(NOW()),MONTH(NOW()),1))-“ & _
“MONTH(DATE(YEAR(NOW()),MONTH(NOW()),1)-“ & _
“(WEEKDAY(DATE(YEAR(NOW()),MONTH(NOW()),1))-1)+” & _
“{0;1;2;3;4;5}*7+{1,2,3,4,5,6,7}-1),”“”“,” & _
“X_X_X())”

theFormulaPart2 = “DATE(YEAR(NOW()),MONTH(NOW()),1)-“ & _
“(WEEKDAY(DATE(YEAR(NOW()),MONTH(NOW()),1))-1)+” & _
“{0;1;2;3;4;5}*7+{1,2,3,4,5,6,7}-1)”

With ActiveSheet.Range(“E2:K7”)
.FormulaArray = theFormulaPart1
.Replace “X_X_X())”, theFormulaPart2
.NumberFormat = “mmm dd”
End With

End Sub
 
Upvote 0
As I said the easiest option with formula is to change the sheet name
VBA Code:
Sheets("Parked Consolidated").Name = "parked"
Range("p2").Select
Selection.FormulaArray = _
"=IFERROR(INDEX('Parked'!C[-8],MATCH(1,([@[Company Code]]='Parked'!C[-15])*([@Vendor]='Parked'!C[-13])*([@[Document Number]]='Parked'!C[-11])*([@[Posting Date]]='Parked'!C[-9]),0)),""Not Assigned"")"
Sheets("Parked").Name = "Parked Consolidated"
 
Upvote 0
Solution
oh wow didnt think of that, great thank you, I will try that,

tried to adapt the code but still ran in the same prob.

will try and let you know. thanks for helping.
 
Upvote 0
You're welcome & thanks for the feedback.
 
Upvote 0

Forum statistics

Threads
1,213,494
Messages
6,113,972
Members
448,537
Latest member
Et_Cetera

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