sum values from the listed sheets

F

foreverzeljo

Hi everybody,

I'm having a little problem with my excel table.

I have many sheets for entering data, they look exactly the same, just
the sheet name is different. Then I also have the summary sheets, that
are also the same as the one for data entry, just they contain
formulas to sum data from data entry sheets.

So what I'm trying to make a list of data entry sheets in the summary
sheet and then the formula that would sum all the data entered in the
listed sheets in the same cell address where the formula is located.

The list of sheets to sum could contain let's say up to 30 places.

And another quick question. Is it possible to somehow link make some
kind of "master formula" and then use it in multiple cells, so when
you change the master formula all the cells that use it change too.

Thanks.
 
F

foreverzeljo1

Hi everybody,

I'm having a little problem with my excel table.

I have many sheets for entering data, they look exactly the same, just
the sheet name is different. Then I also have the summary sheets, that
are also the same as the one for data entry, just they contain
formulas to sum data from data entry sheets.

So what I'm trying to make a list of data entry sheets in the summary
sheet and then the formula that would sum all the data entered in the
listed sheets in the same cell address where the formula is located.

The list of sheets to sum could contain let's say up to 30 places.

And another quick question. Is it possible to somehow link make some
kind of "master formula" and then use it in multiple cells, so when
you change the master formula all the cells that use it change too.

Thanks.

By now I came up with this formula, but it's for a list of 4 sheets
only.

=IF($AE$2="";0;INDIRECT("'"&$AE$2&"'"&"!"&ADDRESS(ROW();COLUMN())))
+IF($AE$3="";0;INDIRECT("'"&$AE$3&"'"&"!"&ADDRESS(ROW();COLUMN())))
+IF($AE$4="";0;INDIRECT("'"&$AE$4&"'"&"!"&ADDRESS(ROW();COLUMN())))
+IF($AE$5="";0;INDIRECT("'"&$AE$5&"'"&"!"&ADDRESS(ROW();COLUMN())))

The sheet names are in AE column.

This certainly won't work for 30 sheets, as the formula would get too
big to enter.
 
R

Roger Govier

Hi

You can use something like
=SUM(Sheet1:Sheet30!A1)

OR, what I prefer, (and it isn't dependent upon having sheets named 1 to
30), you can insert 2 dummy sheets called First and Last.
Drag these so that they encompass your sheets to be summed, in a sort of
"sandwich", with your summary sheet outside of this range. Then
=SUM(First:Last!A1)
 
F

foreverzeljo1

Thanks for your answer Roger. I knew about this formula, but still I
would need the formula to sum according to provided list of data entry
sheets. The formula I wrote in my second post works perfectly, the
only problem is that it's going to be too long to enter if I make it
for 30 sheets.
 
R

Roger Govier

Hi

Then try
=SUMPRODUCT(N(INDIRECT("'"&AE2:AE30&"'!B1")))

You need to ensure that the range AE2:AE30 matches the range that contains
Sheet names.
If there are any blank cells in that range you will get a #REF error.
 
F

foreverzeljo1

Great, this is just what I needed. I just changed the formula so I
could use it in any cell. So now it is:

=SUMPRODUCT(N(INDIRECT("'"&AE2:AE30&"'!"&ADDRESS(ROW();COLUMN()))))

Thanks a lot man, this will be a huge time save for me!

There's just another small problem. As I will have many summary sheets
where many cells will be using this formula, it would be great if I
could somehow make one "master cell" in a sheet where I could make the
changes to the formula(to define the range for sheet names and avoid
the #REF error), which would then be applied to all cells using the
formula.
 
R

Roger Govier

Hi

Define a named range
Insert>Name>Define. Name MyRng Refers to =
OFFSET($AE$2,0,0,COUNTA($AE:$AE))

=SUMPRODUCT(N(INDIRECT("'"&MyRng&"'!"&ADDRESS(ROW();COLUMN()))))
 
F

foreverzeljo1

Hi,

I tried this, but it seems it doesn't work. It gives me the #REF
error, and I've been able to define the range just with the the sheet
names, for example:
=OFFSET(Sheet1!$AE$3;0;0;COUNTA(Sheet1!$AE:$AE))
It won't let me do it without "Sheet1!"

What could be the problem?
 
R

Roger Govier

Hi

Yes it will include the sheet references.
Just ensure that you are on the correct sheet when you define the named
range.
Worked fine for me.
 
F

foreverzeljo1

OK, I got what I want now:

=SUMPRODUCT(N(INDIRECT("'"&OFFSET($AE$2;0;0;COUNTA($AE:
$AE)-1;1)&"'!"&ADDRESS(ROW();COLUMN()))))

This way I don't have to define name for the range and I can use the
formula anywhere on any sheet. Thank you very much Roger, you really
saved me a lot of time. I hope someone else can benefit from this too.

Best regards.
 

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