Converting old school formula to dynamic array

Berek

New Member
Joined
Apr 11, 2012
Messages
10
Office Version
  1. 365
Platform
  1. Windows
Hey there,
I use Microsoft 365 on Windows 10 Home

Can these two old school formulae be converted into dynamic arrays so that they catch new names in the unique list and spill down so that I don't need to use locked cell references?

The table I have is updated weekly and be be up to 300,000 rows over the year. It takes about 30 minutes to run through the calcuations. I figured if they can be coverted to dynamic arrays and not have to use locked cell references it might take less time.


=COUNT(IF(I$4:I$300=N4,IF(ROW(I$4:I$300)>=LARGE(IF(I$4:I$300=N4,ROW(I$4:I$300)),MIN(COUNTIF(I$4:I$300,N4),$N$2)),0)))


=COUNT(IF($K$4:$K$300=1,IF($I$4:$I$300=N4,IF(ROW(I$4:I$300)>=LARGE(IF($I$4:$I$300=N4,ROW(I$4:I$300)),MIN(COUNTIF($I$4:$I$300,N4),$N$2)),$K$4:$K$300))))


Thanks
Berek


MrExcel Query.xlsx
ABCDEFGHIJKLMNOPQRS
1N1Old School FormulaePOSSIBLE ARRAY FORMULAE?
212
3DateRepsKeyNumberAreaDateRepsKeyNumberAreaUnique ListABAB
406/04/2019AaronN113906/04/2019AaronN1139Aaron21
513/04/2019AaronN114813/04/2019AaronN1148Bobby21
613/04/2019AaronN124213/04/2019AaronN1242Catherine20
721/04/2019AaronN226007/05/2019BobbyN129Peter
821/04/2019AaronN369207/05/2019BobbyN1146
924/04/2019AaronN309120/08/2019CatherineN1618
1026/04/2019AaronN418725/08/2019CatherineN13051
1126/04/2019AaronN445402/09/2019CatherineN12064
1207/05/2019BobbyN12903/05/2021PeterN1230
1307/05/2019BobbyN114606/05/2021PeterN1221
1412/05/2019BobbyN2917
1520/05/2019BobbyN2037
1621/05/2019BobbyN3195
1725/05/2019BobbyN3343
1803/06/2019BobbyN3364
1917/06/2019BobbyN3888
2020/06/2019BobbyN41278
2120/07/2019BobbyN4022
2210/08/2019BobbyN4130
2312/08/2019BobbyN5898
2419/08/2019BobbyN5045
2520/08/2019CatherineN1618
2625/08/2019CatherineN13051
2702/09/2019CatherineN12064
2803/05/2021PeterN1230
2906/05/2021PeterN1221
Sheet1
Cell Formulas
RangeFormula
H4:L13H4=SORT(FILTER(Table1,Table1[Key]=N1))
N4:N7N4=SORT(UNIQUE(Table1[Reps]))
O4:O6O4=COUNT(IF(I$4:I$300=N4,IF(ROW(I$4:I$300)>=LARGE(IF(I$4:I$300=N4,ROW(I$4:I$300)),MIN(COUNTIF(I$4:I$300,N4),$N$2)),0)))
P4:P6P4=COUNT(IF($K$4:$K$300=$M$2,IF($I$4:$I$300=N4,IF(ROW(I$4:I$300)>=LARGE(IF($I$4:$I$300=N4,ROW(I$4:I$300)),MIN(COUNTIF($I$4:$I$300,N4),$N$2)),$K$4:$K$300))))
Dynamic array formulas.
 
@Berek
Do you have the LET function (some 365 users do and some don't)?
To check, click the fx button and choose 'Text' category, is LET in the list?

1620630538940.png
 
Upvote 0

Excel Facts

What is =ROMAN(40) in Excel?
The Roman numeral for 40 is XL. Bill "MrExcel" Jelen's 40th book was called MrExcel XL.
Do you have the LET function
Assuming the answer is "Yes"** see how these go. They need to be copied down as far as you might ever need to accommodate any subsequent automatic expansion of the spill range in column N.

** If the answer turns out to be "No", the formulas can be adjusted.

Berek.xlsm
ABCDEFGHIJKLMNOPQRS
1N1OldNew
212
3DateRepsKeyNumberAreaDateRepsKeyNumberAreaUnique ListABAB
46/04/2019AaronN11396/04/2019AaronN1139Aaron2121
513/04/2019AaronN114813/04/2019AaronN1148Bobby2121
613/04/2019AaronN124213/04/2019AaronN1242Catherine2020
721/04/2019AaronN22607/05/2019BobbyN129Peter2020
821/04/2019AaronN36927/05/2019BobbyN1146  
924/04/2019AaronN309120/08/2019CatherineN1618  
1026/04/2019AaronN418725/08/2019CatherineN13051  
1126/04/2019AaronN44542/09/2019CatherineN12064  
127/05/2019BobbyN1293/05/2021PeterN1230  
137/05/2019BobbyN11466/05/2021PeterN1221  
1412/05/2019BobbyN2917  
1520/05/2019BobbyN2037
1621/05/2019BobbyN3195
1725/05/2019BobbyN3343
183/06/2019BobbyN3364
1917/06/2019BobbyN3888
2020/06/2019BobbyN41278
2120/07/2019BobbyN4022
2210/08/2019BobbyN4130
2312/08/2019BobbyN5898
2419/08/2019BobbyN5045
2520/08/2019CatherineN1618
2625/08/2019CatherineN13051
272/09/2019CatherineN12064
283/05/2021PeterN1230
296/05/2021PeterN1221
30
Sheet1
Cell Formulas
RangeFormula
H4:L13H4=SORT(FILTER(Table1,Table1[Key]=N1))
N4:N7N4=SORT(UNIQUE(Table1[Reps]))
O4:O7O4=COUNT(IF(I$4:I$300=N4,IF(ROW(I$4:I$300)>=LARGE(IF(I$4:I$300=N4,ROW(I$4:I$300)),MIN(COUNTIF(I$4:I$300,N4),$N$2)),0)))
P4:P7P4=COUNT(IF($K$4:$K$300=$M$2,IF($I$4:$I$300=N4,IF(ROW(I$4:I$300)>=LARGE(IF($I$4:$I$300=N4,ROW(I$4:I$300)),MIN(COUNTIF($I$4:$I$300,N4),$N$2)),$K$4:$K$300))))
R4:R14R4=IF(N4="","",LET(nums,INDEX(H$4#,0,4),names,INDEX(H$4#,0,2),COUNT(FILTER(nums,(names=N4)*(ROW(nums)>=MAX(XMATCH(N4,I:I,0,-1)-N$2+1,1)),""))))
S4:S14S4=IF(N4="","",LET(nums,INDEX(H$4#,0,4),names,INDEX(H$4#,0,2),COUNT(FILTER(nums,(names=N4)*(ROW(nums)>=MAX(XMATCH(N4,I:I,0,-1)-N$2+1,1))*(nums=M$2),""))))
Dynamic array formulas.
 
Upvote 0
Solution
Hi Peter,
Brilliant! Thanks for your help. That works so well I can't believe it. It ran the calculations on over 330,000 rows of data in a just a few minutes... and it's all accurate.

Great work, now I have look for the tick to say it's been solved.

Berek
 
Upvote 0
You're welcome. Thanks for the follow-up. :)

.. and it looks like you found the tick. :cool:
 
Upvote 0

Forum statistics

Threads
1,213,550
Messages
6,114,265
Members
448,558
Latest member
aivin

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