Google Groups no longer supports new Usenet posts or subscriptions. Historical content remains viewable.
Dismiss

COUNTIF across multiple worksheets

0 views
Skip to first unread message

merlin

unread,
Sep 18, 2006, 3:54:04 PM9/18/06
to
I need to add up the number of times there is a "Y" in a cell on a
multi-worksheet questionnaire (one sheet per respondant).

COUNTIF doesn't seem to work across multiple sheets. Is there a way around
this (without resorting to VBA)?

I'm thinking I might have to double up on each sheet, convert the Ys to 1s
and sum them.


Bob Phillips

unread,
Sep 18, 2006, 5:44:13 PM9/18/06
to
=SUMPRODUCT(COUNTIF(INDIRECT("'"&C1:C3&"'!B1:B10"),"Y"))

where C1:C3 is a range housing the relevant sheetnames in
separate cells, and B1:B10 is the range being checked.


--
HTH

Bob Phillips

(replace somewhere in email address with gmail if mailing direct)

"merlin" <mer...@johnconstable.net> wrote in message
news:115860926...@iris.uk.clara.net...

merlin

unread,
Sep 18, 2006, 6:28:15 PM9/18/06
to
OK - I've changed it to

=SUMPRODUCT(COUNTIF(INDIRECT("'"&$L$2:$L$5&"'!D11"),"Y"))

so I can just summarise 1 cell at a time. Works beautifully - thanks Bob!

It's a shame that the cell references don't update when I cut and paste the
formulas - I'll have to change each manually but it's a small price to
pay...


"Bob Phillips" <bob...@somewhere.com> wrote in message
news:ejOWiu22...@TK2MSFTNGP06.phx.gbl...

Bob Phillips

unread,
Sep 18, 2006, 6:39:36 PM9/18/06
to
If you are just going down rows, you could try

=SUMPRODUCT(COUNTIF(INDIRECT("'"&$L$2:$L$5&"'!D"&ROW(A11)),"Y"))

which will increment

--
HTH

Bob Phillips

(replace somewhere in email address with gmail if mailing direct)

"merlin" <mer...@johnconstable.net> wrote in message

news:11586185...@iris.uk.clara.net...

merlin

unread,
Sep 18, 2006, 7:00:05 PM9/18/06
to
genius.

Is it the ! that stops the incrementation?

Can I use COLUMN in the same way to getthe columns to increment i.e.:

=SUMPRODUCT(COUNTIF(INDIRECT("'"&$L$2:$L$5&"'!COLUMN(D1)"&ROW(A11)),"Y"))

"Bob Phillips" <bob...@somewhere.com> wrote in message

news:elDyfN32...@TK2MSFTNGP06.phx.gbl...

Bob Phillips

unread,
Sep 18, 2006, 7:23:27 PM9/18/06
to
No, it is the text within INDIRECT.

Column is harder, and it is late here. I'll work on it tomorrow, check back
then.

--
HTH

Bob Phillips

(replace somewhere in email address with gmail if mailing direct)

"merlin" <mer...@johnconstable.net> wrote in message

news:11586204...@iris.uk.clara.net...

Bob Phillips

unread,
Sep 18, 2006, 7:31:36 PM9/18/06
to
Just cracked it

=SUMPRODUCT(COUNTIF(INDIRECT("'"&$L$2:$L$5&"'!"&ADDRESS(ROW(D11),COLUMN(D11)
,4)),"Y"))

--
HTH

Bob Phillips

(replace somewhere in email address with gmail if mailing direct)

"Bob Phillips" <bob...@somewhere.com> wrote in message
news:eUt6Am32...@TK2MSFTNGP04.phx.gbl...

merlin

unread,
Sep 19, 2006, 4:53:21 PM9/19/06
to
magic - thanks, Bob.

"Bob Phillips" <bob...@somewhere.com> wrote in message

news:uCyFlq32...@TK2MSFTNGP03.phx.gbl...

0 new messages