Array function in excel VBA

knaabis

Active Member
Joined
Apr 25, 2006
Messages
254
Office Version
  1. 2013
Platform
  1. Windows
Why this doesn't work in VBA?

.Cells(1, 1).FormulaArray = "=IF(ROWS(ca$27:ca27)<=$ba$1,INDEX(\\LVSERVER\Company\Production\Razosana\Jaunie\[CutList2.xlsm]Pre!$d$2:$d$8000,SMALL(IF(\\LVSERVER\Company\Production\Razosana\Jaunie\[CutList2.xlsm]Pre!$A$2:$A$8000=$BM$2,IF(\\LVSERVER\Company\Production\Razosana\Jaunie\[CutList2.xlsm]Pre!$p$2:$p$8000=$BN$2,IF(\\LVSERVER\Company\Production\Razosana\Jaunie\[CutList2.xlsm]Pre!$w$2:$w$8000<>$BO$2,IF(\\LVSERVER\Company\Production\Razosana\Jaunie\[CutList2.xlsm]Pre!$I$2:$I$8000=$BP$2,ROW(\\LVSERVER\Company\Production\Razosana\Jaunie\[CutList2.xlsm]Pre!$d$2:$d$8000)-ROW(\\LVSERVER\Company\Production\Razosana\Jaunie\[CutList2.xlsm]Pre!$d$2)+1)))),ROWS(ca$27:ca27))),"""")"

If instead of this - \\LVSERVER\Company\Production\Razosana\Jaunie\[CutList2.xlsm]Pre!
i add only this - [CutList2.xlsm]Pre! (when file CutList2.xlsm is open)
then all is ok.

Where is a problem?
 

Excel Facts

Workdays for a market open Mon, Wed, Friday?
Yes! Use "0101011" for the weekend argument in NETWORKDAYS.INTL or WORKDAY.INTL. The 7 digits start on Monday. 1 means it is a weekend.
You've exceeded the length for a formula array, try
Code:
With .Cells(1, 1)
   .FormulaArray = "=IF(ROWS(ca$27:ca27)<=$ba$1,INDEX(Pre!$d$2:$d$8000,SMALL(IF(Pre!$A$2:$A$8000=$BM$2,IF(Pre!$p$2:$p$8000=$BN$2,IF(Pre!$w$2:$w$8000<>$BO$2,IF(Pre!$I$2:$I$8000=$BP$2,ROW(Pre!$d$2:$d$8000)-ROW(Pre!$d$2)+1)))),ROWS(ca$27:ca27))),"""")"
   .Replace "Pre", "\\LVSERVER\Company\Production\Razosana\Jaunie\[CutList2.xlsm]Pre"
End With
 
Upvote 0

Forum statistics

Threads
1,213,491
Messages
6,113,963
Members
448,536
Latest member
CantExcel123

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