Summing across multiple sheets with a twist

H

hillmic

Every week a new worksheet ("tab") is made by copying the prior week'
tab and adding pertinent data for the week. Several of the cells i
each "tab" are a summation across all prior worksheets/tabs, givin
Year-To-Date totals. I figured out how to do this by clicking th
leftmost "tab" and then shift-clicking the rightmost tab.

My issue: I'd like for this to automatically happen when I create
new tab, but I get #REF's for all these references as soon as I mak
the copy.

I've got an idea for a workaround, but I can't get it to work:
1) Put a cell in each "tab" with the name of the "tab"... e.g. cell C
has "525" in it.
2) In the year-to-date summation cells which normally would have
formula like: =SUM('501:525'!X7)
I've tried putting =SUM('501:C3'!X7).
Didn't work.
I've tried putting =SUM('501:"C3"'!X7) thinking maybe the quotes woul
let Excel know I'm trying to insert a "text string" where th
sheetname/tab would normally be.
Didn't work.

Basically, I'm asking if there's a way to force a sheetname into
formula by making a reference to a cell with that sheetname in it?

Or does anyone know a better workaround for what I'm trying t
accomplish?

Right now, I just manually go in and redo all the #REF's... no big dea
but my curiosity has got the better of me.

Thank
 
B

Bob Phillips

Try

=SUM(INDIRECT("'501:"&C3&"'!X7"))

although this would suggest that all you need is the last sheet name in the
summary tab, not on each.

--

HTH

RP
(remove nothere from the email address if mailing direct)
 
D

Domenic

Try...

=SUMPRODUCT(N(INDIRECT("'"&ROW(INDIRECT("501:"&C3))&"'!X7")))

Hope this helps!
 
B

Bob Phillips

oops, seeing Domenic's answer reminds me that this method doesn't work
across sheets, sorry about that.

--

HTH

RP
(remove nothere from the email address if mailing direct)


Bob Phillips said:
Try

=SUM(INDIRECT("'501:"&C3&"'!X7"))

although this would suggest that all you need is the last sheet name in the
summary tab, not on each.

--

HTH

RP
(remove nothere from the email address if mailing direct)
 
H

hillmic

I have no idea why... but it works! Thank you so much.

I'm curious why the indirect text argument will work in sumproduct but
wouldn't work in sum.
 
D

Domenic

hillmic said:
I have no idea why... but it works! Thank you so much.

I'm curious why the indirect text argument will work in sumproduct but
wouldn't work in sum.

Good question! I wish I knew! :)
 

Ask a Question

Want to reply to this thread or ask your own question?

You'll need to choose a username for the site, which only take a couple of moments. After that, you can post your question and our members will help you out.

Ask a Question

Top