Excel out of resources!? Issue with using AVERAGE(IF(...

brucewflee

New Member
Joined
Nov 8, 2014
Messages
12
Greetings to the almighty Excel community,

I have an excel file which was running fine until I have implemented an "AVERAGE(IF(..." and is slowing down the calculations. It has got to a point where it is prompting out the error message "Excel ran out of resources while attempting to calculate one or more formulas. As a result, these formulas cannot be evaluated. ".

The offending formula is carrying out a function where it will average a certain column when the column header is matching with a criteria name and the corresponding rows are also carrying values.

Column AColumn BColumn CColumn DColumn EColumn F
Row 1AppleOrangePear
Row 235Apple2
Row 32
Row 41
Row 516

<tbody>
</tbody>


Array formula in F2 = {AVERAGE(IF($A$1:$C$1=$E2,IF(ISNUMBER($A:$C),$A:$C)))}

To make the matter worse, I have at least 30 of these array formula running at the same time. I am guessing that by changing "$A:$C" into "$A1:$C1000" will help speeding up, but I have already had 100,000 (rows) x 30 (columns) of data and is growing by days so I would really like it to look for the whole columns.

Is there any straightforward function that can carry out the same task? It would be appreciated if someone can help simplifying the formula or providing a solution.

Thank you very much for the help in advance.
 

Excel Facts

When they said...
When they said you are going to "Excel at life", they meant you "will be doing Excel your whole life".
Try
Code:
=AVERAGE(INDEX($A:$C,0,MATCH(E2,$A$1:$C$1,0)))

Average ignores non numeric values; no need to check for that.
 
Upvote 0

Forum statistics

Threads
1,215,839
Messages
6,127,199
Members
449,368
Latest member
JayHo

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