Find largest number across multiple sheets using INDIRECT

aloring

New Member
Joined
Nov 5, 2018
Messages
4
I'm trying to find the Largest number (in column A) across a number of worksheets, but I need the names of the worksheets to be dynamic.
I can do this with a single worksheet, but using a colon separator within the worksheets seems to cause the formula to have a #REF ! error.

I have the names of the worksheets in Column A (on sheet1) and am then trying to use this formula to get the largest number from the other sheets:
=LARGE(INDIRECT("'"&$A$2&":"&$A$5&"'!A:A"),1)

Can anybody spot what I'm doing wrong, or suggest another formula to do this (I'm using LARGE as opposed to MAX because I will then want to show the second and third largets numbers etc.)
 

Excel Facts

Did you know Excel offers Filter by Selection?
Add the AutoFilter icon to the Quick Access Toolbar. Select a cell containing Apple, click AutoFilter, and you will get all rows with Apple
I haven't used the LARGE function before but it looks like your missing a row reference in the last part of your formula. Have you tried evaluating the formula so you can see which part of the calculation is giving you the trouble?
 
Upvote 0
Yes, sheet names are listed in A2:A5 (on sheet1), so the formula should be returning " 'Name_A:Name_B'!A:A " which works when entered manually, but now via INDIRECT
 
Upvote 0
I haven't used the LARGE function before but it looks like your missing a row reference in the last part of your formula. Have you tried evaluating the formula so you can see which part of the calculation is giving you the trouble?
It doesn't need row references because "A:A" will reference all rows in column A, but thanks for the help.
 
Upvote 0
would it work for you to create a blank sheet (called Start) and put it before the sheet named in A1.
And another sheet (named End) after the A5 sheet.
Then =MAX(Start:End!$A:$A) should get what you want.


Start and End can be hidden after they are created.
 
Upvote 0
would it work for you to create a blank sheet (called Start) and put it before the sheet named in A1.
And another sheet (named End) after the A5 sheet.
Then =MAX(Start:End!$A:$A) should get what you want.


Start and End can be hidden after they are created.

Yes, thanks Mike, that's an option, albeit with LARGE not MAX (although I'd have to amend the other formulae which refer to worksheets.count), but I'm still confused as to why the INDIRECT isn't working!
 
Upvote 0
Hi,

mikerickson's suggestion is by far the most practical, though for Excel 2010 and later you could also use the following array formula**:

=MAX(AGGREGATE(4,,A2,INDIRECT("'"&A2:A5&"'!A:A")))

Regards


**Array formulas are not entered in the same way as 'standard' formulas. Instead of pressing just ENTER, you first hold down CTRL and SHIFT, and only then press ENTER. If you've done it correctly, you'll notice Excel puts curly brackets {} around the formula (though do not attempt to manually insert these yourself).
 
Upvote 0
Yes, sheet names are listed in A2:A5 (on sheet1), so the formula should be returning " 'Name_A:Name_B'!A:A " which works when entered manually, but now via INDIRECT

Just enter and copy down:

=LARGE(First:Last!$A:A,ROWS($1:1))

where First and Last are two new sheets which envelops the relevant sheets.

Or control+shift+enter, not just enter, and copy down:

=LARGE(N(OFFSET(INDIRECT("'"&TRANSPOSE($A$2:$A$5)&"'!A2:A2000"),ROW(A2:A2000)-ROW(A2),0)),ROWS($1:1))
 
Upvote 0

Forum statistics

Threads
1,215,522
Messages
6,125,312
Members
449,218
Latest member
Excel Master

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