Offset formula across multiple sheets

flexinau

Board Regular
Joined
Sep 22, 2002
Messages
122
Using the formula below produces an error. Is there a way to sum across sheets to get the results I am trying to produce with the formula below?

=SUM(OFFSET(Sheet1!:Sheet5!A9,1,5))

thanks
 

Excel Facts

Which came first: VisiCalc or Lotus 1-2-3?
Dan Bricklin and Bob Frankston debuted VisiCalc in 1979 as a Visible Calculator. Lotus 1-2-3 debuted in the early 1980's, from Mitch Kapor.
Try...

=SUMPRODUCT(N(OFFSET(INDIRECT("Sheet"&ROW(INDIRECT("1:5"))&"!A9"),1,5)))

or

=SUMPRODUCT(N(OFFSET(INDIRECT("'"&A1:A5&"'!A9"),1,5)))

...where A1:A5 contains your sheet names.

Hope this helps!
 
Upvote 0
I used the second formula and it work but I have a question.

If the offset formula returns a value, then why use the n formula to convert to a number?
 
Upvote 0
flexinau said:
If the offset formula returns a value, then why use the n formula to convert to a number?

Actually, OFFSET/INDIRECT returns an 'array of references'. The N() function is used to de-reference. Basically, to make the values available from the references.
 
Upvote 0
What is the reason for specifying the target cell to sum by means of volatile functions (OFFSET, INDIRECT) which also forces you to abandon a simple 3D SUM?
 
Upvote 0

Forum statistics

Threads
1,213,484
Messages
6,113,923
Members
448,533
Latest member
thietbibeboiwasaco

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