VBA- Array Formula with Dynamic Last Cell

willwill88

New Member
Joined
Dec 8, 2011
Messages
5
Hi,

I'm trying to make an array formula with vba where the logical test stops at the last row. I'm hoping this will speed up the macro instead of scanning a whole column C:C for example, which could have 2,000 - 600,000+ rows.

Sheet 1 has the data
Sheet 4 is where im putting the fomula

I was hoping this forumla would work but no dice. Any help would be appreciated.

Selection.FormulaArray = _
"=MAX(IF(C2=(Sheet1(C2:C & LastRow),(Sheet1.Range(U2:U & LastRow),""""))"


Code:
Sheets(1).Activate
LastCol = Cells(2, Columns.Count).End(xlToLeft).Column
LastRow = Cells(Rows.Count, "B").End(xlUp).Row
Sheets(4).Activate
Range("AI2").Select

Code works but is slow
Selection.FormulaArray = _
"=MAX(IF(RC[-32]='Reservation Details By Date'!C[-32],'Reservation Details By Date'!C[-14],""""))"

'Error with this code
Selection.FormulaArray = _
"=MAX(IF(C2=(Sheet1(C2:C & LastRow),(Sheet1.Range(U2:U & LastRow),""""))"

'Error with this code
Selection.FormulaArray = _
"=MAX(IF(C[-32]=(Sheet1(C[-32] & LastRow),(Sheet1.Range(C[-14] & LastRow),""""))"
 

Some videos you may like

Excel Facts

Excel motto
Not everything I do at work revolves around Excel. Only the fun parts.

Sal Paradise

Well-known Member
Joined
Oct 23, 2006
Messages
2,457
You could do the same with named ranges and then don't need VBA:

ColA is:
=OFFSET(Sheet2!$A$1,1,0,COUNTA(Sheet2!$A:$A)-1,1)

ColB is:
=OFFSET(Sheet2!$B$1,1,0,COUNTA(Sheet2!$B:$B)-1,1)

So here are the formulas:
<b>Excel 2003</b><table cellpadding="2.5px" rules="all" style=";background-color: #FFFFFF;border: 1px solid;border-collapse: collapse; border-color: #A6AAB6"><colgroup><col width="25px" style="background-color: #E0E0F0" /><col /><col /><col /></colgroup><thead><tr style=" background-color: #E0E0F0;text-align: center;color: #161120"><th></th><th>A</th><th>B</th><th>C</th></tr></thead><tbody><tr ><td style="color: #161120;text-align: center;">1</td><td style=";">ColA</td><td style=";">ColB</td><td style=";">Formula</td></tr><tr ><td style="color: #161120;text-align: center;">2</td><td style=";">B</td><td style="text-align: right;;">8</td><td style="text-align: right;;">10</td></tr><tr ><td style="color: #161120;text-align: center;">3</td><td style=";">C</td><td style="text-align: right;;">6</td><td style="text-align: right;;">10</td></tr><tr ><td style="color: #161120;text-align: center;">4</td><td style=";">B</td><td style="text-align: right;;">4</td><td style="text-align: right;;">10</td></tr><tr ><td style="color: #161120;text-align: center;">5</td><td style=";">E</td><td style="text-align: right;;">4</td><td style="text-align: right;;">9</td></tr><tr ><td style="color: #161120;text-align: center;">6</td><td style=";">A</td><td style="text-align: right;;">5</td><td style="text-align: right;;">9</td></tr><tr ><td style="color: #161120;text-align: center;">7</td><td style=";">E</td><td style="text-align: right;;">8</td><td style="text-align: right;;">9</td></tr><tr ><td style="color: #161120;text-align: center;">8</td><td style=";">B</td><td style="text-align: right;;">8</td><td style="text-align: right;;">10</td></tr><tr ><td style="color: #161120;text-align: center;">9</td><td style=";">D</td><td style="text-align: right;;">1</td><td style="text-align: right;;">10</td></tr><tr ><td style="color: #161120;text-align: center;">10</td><td style=";">E</td><td style="text-align: right;;">1</td><td style="text-align: right;;">9</td></tr><tr ><td style="color: #161120;text-align: center;">11</td><td style=";">E</td><td style="text-align: right;;">3</td><td style="text-align: right;;">9</td></tr><tr ><td style="color: #161120;text-align: center;">12</td><td style=";">D</td><td style="text-align: right;;">9</td><td style="text-align: right;;">10</td></tr><tr ><td style="color: #161120;text-align: center;">13</td><td style=";">E</td><td style="text-align: right;;">7</td><td style="text-align: right;;">9</td></tr><tr ><td style="color: #161120;text-align: center;">14</td><td style=";">A</td><td style="text-align: right;;">8</td><td style="text-align: right;;">9</td></tr><tr ><td style="color: #161120;text-align: center;">15</td><td style=";">B</td><td style="text-align: right;;">4</td><td style="text-align: right;;">10</td></tr><tr ><td style="color: #161120;text-align: center;">16</td><td style=";">B</td><td style="text-align: right;;">5</td><td style="text-align: right;;">10</td></tr><tr ><td style="color: #161120;text-align: center;">17</td><td style=";">A</td><td style="text-align: right;;">3</td><td style="text-align: right;;">9</td></tr><tr ><td style="color: #161120;text-align: center;">18</td><td style=";">B</td><td style="text-align: right;;">1</td><td style="text-align: right;;">10</td></tr><tr ><td style="color: #161120;text-align: center;">19</td><td style=";">B</td><td style="text-align: right;;">9</td><td style="text-align: right;;">10</td></tr><tr ><td style="color: #161120;text-align: center;">20</td><td style=";">D</td><td style="text-align: right;;">5</td><td style="text-align: right;;">10</td></tr><tr ><td style="color: #161120;text-align: center;">21</td><td style=";">B</td><td style="text-align: right;;">10</td><td style="text-align: right;;">10</td></tr><tr ><td style="color: #161120;text-align: center;">22</td><td style=";">D</td><td style="text-align: right;;">10</td><td style="text-align: right;;">10</td></tr><tr ><td style="color: #161120;text-align: center;">23</td><td style=";">B</td><td style="text-align: right;;">9</td><td style="text-align: right;;">10</td></tr><tr ><td style="color: #161120;text-align: center;">24</td><td style=";">E</td><td style="text-align: right;;">9</td><td style="text-align: right;;">9</td></tr><tr ><td style="color: #161120;text-align: center;">25</td><td style=";">A</td><td style="text-align: right;;">8</td><td style="text-align: right;;">9</td></tr><tr ><td style="color: #161120;text-align: center;">26</td><td style=";">A</td><td style="text-align: right;;">9</td><td style="text-align: right;;">9</td></tr><tr ><td style="color: #161120;text-align: center;">27</td><td style=";">E</td><td style="text-align: right;;">4</td><td style="text-align: right;;">9</td></tr><tr ><td style="color: #161120;text-align: center;">28</td><td style=";">C</td><td style="text-align: right;;">2</td><td style="text-align: right;;">10</td></tr><tr ><td style="color: #161120;text-align: center;">29</td><td style=";">D</td><td style="text-align: right;;">6</td><td style="text-align: right;;">10</td></tr><tr ><td style="color: #161120;text-align: center;">30</td><td style=";">C</td><td style="text-align: right;;">10</td><td style="text-align: right;;">10</td></tr><tr ><td style="color: #161120;text-align: center;">31</td><td style=";">C</td><td style="text-align: right;;">7</td><td style="text-align: right;;">10</td></tr></tbody></table><p style="width:3.6em;font-weight:bold;margin:0;padding:0.2em 0.6em 0.2em 0.5em;border: 1px solid #A6AAB6;border-top:none;text-align: center;background-color: #E0E0F0;color: #161120">Sheet2</p><br /><br /><table width="85%" cellpadding="2.5px" rules="all" style=";border: 2px solid black;border-collapse:collapse;padding: 0.4em;background-color: #FFFFFF" ><tr><td style="padding:6px" ><b>Array Formulas</b><table cellpadding="2.5px" width="100%" rules="all" style="border: 1px solid;text-align:center;background-color: #FFFFFF;border-collapse: collapse; border-color: #A6AAB6"><thead><tr style=" background-color: #E0E0F0;color: #161120"><th width="10px">Cell</th><th style="text-align:left;padding-left:5px;">Formula</th></tr></thead><tbody><tr><th width="10px" style=" background-color: #E0E0F0;color: #161120">C2</th><td style="text-align:left">{=MAX(<font color="Blue">IF(<font color="Red">A2=ColA,ColB</font>)</font>)}</td></tr></tbody></table><b>Entered with Ctrl+Shift+Enter.</b> If entered correctly, Excel will surround with curly braces {}.
<b>Note: Do not try and enter the {} manually yourself</b></td></tr></table><br /><table width="85%" cellpadding="2.5px" rules="all" style=";border: 2px solid black;border-collapse:collapse;padding: 0.4em;background-color: #FFFFFF" ><tr><td style="padding:6px" ><b>Workbook Defined Names</b><table cellpadding="2.5px" width="100%" rules="all" style="border: 1px solid;text-align:center;background-color: #FFFFFF;border-collapse: collapse; border-color: #A6AAB6"><thead><tr style=" background-color: #E0E0F0;color: #161120"><th width="10px">Name</th><th style="text-align:left">Refers To</th></tr></thead><tbody><tr><th width="10px" style=" background-color: #E0E0F0;color: #161120">ColA</th><td style="text-align:left">=OFFSET(<font color="Blue">Sheet2!$A$1,1,0,COUNTA(<font color="Red">Sheet2!$A:$A</font>)-1,1</font>)</td></tr><tr><th width="10px" style=" background-color: #E0E0F0;color: #161120">ColB</th><td style="text-align:left">=OFFSET(<font color="Blue">Sheet2!$B$1,1,0,COUNTA(<font color="Red">Sheet2!$B:$B</font>)-1,1</font>)</td></tr></tbody></table></td></tr></table><br />

No need for VBA.
 

Watch MrExcel Video

Forum statistics

Threads
1,122,517
Messages
5,596,620
Members
414,081
Latest member
Subaru_Steve

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
Top