Counting across multiple worksheets within a workbook

rickkulh

New Member
Joined
Oct 3, 2006
Messages
4
Hello,

Say I have a 15 tab workbook. Each tab is the same but some contents of certain cells change (kind of like a survey where answers may be different but not exactly). For example, I would like to be able to create a 16th tab where cell A1 in the new tab would show how many times cell A1 in tabs 1 through 15 were populated with a lowercase "o". Any help on this would be greatly appreciated.

Thanks,
Rick
 

Excel Facts

When did Power Query debut in Excel?
Although it was an add-in in Excel 2010 & Excel 2013, Power Query became a part of Excel in 2016, in Data, Get & Transform Data.
Welcome to the Board!

Check the Excel helpfile for: "Refer to the same cell or range on multiple sheets." There is a list of formulas that can be used in 3D references. Unfortunately COUNTIF isn't one of them.

But you could use VBA:

<font face=Tahoma><SPAN style="color:#00007F">Sub</SPAN> Foo()
    <SPAN style="color:#00007F">Dim</SPAN> x <SPAN style="color:#00007F">As</SPAN> <SPAN style="color:#00007F">Integer</SPAN>, y <SPAN style="color:#00007F">As</SPAN> <SPAN style="color:#00007F">Integer</SPAN>
    
        <SPAN style="color:#00007F">For</SPAN> x = 1 <SPAN style="color:#00007F">To</SPAN> Sheets.Count - 1
            <SPAN style="color:#00007F">If</SPAN> Sheets(x).Range("A1") = "o" <SPAN style="color:#00007F">Then</SPAN>
                y = y + 1
            <SPAN style="color:#00007F">End</SPAN> <SPAN style="color:#00007F">If</SPAN>
        <SPAN style="color:#00007F">Next</SPAN> x
        
        MsgBox y
        
<SPAN style="color:#00007F">End</SPAN> <SPAN style="color:#00007F">Sub</SPAN></FONT>

Hope that helps,

Smitty

Jeesh, Aladin never ceases to amaze! :)
 
Upvote 0
On the 16th sheet, list all the relevant sheets in a vertical range (say in A2:A16) and name this vertical range SheetList via the Name Box.

In B2 enter: o

In C2 invoke:

=SUMPRODUCT((CODE(T(INDIRECT("'"&SheetList&"'!A1")))=CODE(B2))+0)
 
Upvote 0
Aladin, you beat me to it. But depending upon the risk of someone renaming a sheet, which woul dcause this method to stop functioning, I would propose the following formula for each entry in the list of sheet names:

Code:
=RIGHT(CELL("filename",sheet1!A1),LEN(CELL("filename",sheet1!A1))-FIND("]",CELL("filename",sheet1!A1)))
adjusted for each sheet in your book. This will always update the names in the list in the event that a sheet gets renamed.
 
Upvote 0
Aladin, you beat me to it. But depending upon the risk of someone renaming a sheet, which woul dcause this method to stop functioning, I would propose the following formula for each entry in the list of sheet names:

Code:
=RIGHT(CELL("filename",sheet1!A1),LEN(CELL("filename",sheet1!A1))-FIND("]",CELL("filename",sheet1!A1)))
adjusted for each sheet in your book. This will always update the names in the list in the event that a sheet gets renamed.

Wouldn't that be too costly even with old XL macro's (PaddyD has a post on this)? Better a piece of VBA code that would create the SheetList instantly...
 
Upvote 0
Wouldn't that be too costly even with old XL macro's (PaddyD has a post on this)? Better a piece of VBA code that would create the SheetList instantly...

I admit that I only have a nebulous understanding of what is processor intensive, and what is not... do you happen to have a reference to PaddyD's post... I'd like to learn more.
 
Upvote 0
Upvote 0

Forum statistics

Threads
1,213,538
Messages
6,114,218
Members
448,554
Latest member
Gleisner2

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