Complicated Vlookup/count problem

S

swjtx

Hi,

What I am trying to do is a kind of distribution. What I want to come
to is something like this:

Book#------How long to read?------
1234 1-2 hours? 2-3 hours? 3-4 hours?
more than 4 hours.

1234 7 11
6 1


The data is on one sheet and I did a quick pivot on sheet2 to get all
unique book numbers. Now in each row on sheet 2 (in the columns next to
the unique book number) I would like the count of how many times a value
(hours) appears in the hours column of the specified book. The first
sheet containing the data looks something like this:

Name Book Hours
Jenny 1234 2.25
Bart 1234 2
Martha 1234 6
Bill 7958 11
Bob 1234 1.5

The trick is to have the function look for a match of the sheet 2 book
number to sheet 1 and count how many times a value appears (on sheet 1)
that falls between a range. Since I have thousands of books, I need the
funtion to search instead of me.

Seems like I need a vlookup combined with a count function or perhaps I
am just confused.

Thanks,

swjtx
 
N

N Harkawat

say your sata on sheet1 on is in the range A2 to c6000 where column B
contains the name of the book and column C contains how long it took to
finishe reading.

On sheet 2 where you have the unique names of the books on Column A; type on
cell B2 the following to count # between 0-2 hrs
=SUMPRODUCT(--(Sheet1!$B$2:$B$6000=$A2),--(Sheet1!$C$2:$C$6000<=2))
on cell C2 for COUNT # between 2-3 hrs
=SUMPRODUCT(--(Sheet1!$B$2:$B$6000=$A2),--(Sheet1!$C$2:$C$6000>2),--(Sheet1!$C$2:$C$6000<=3)))
for 3-4 hrs on D2
=SUMPRODUCT(--(Sheet1!$B$2:$B$6000=$A2),--(Sheet1!$C$2:$C$6000>3),--(Sheet1!$C$2:$C$6000<=4)))
for > 4 hrs on E2
=SUMPRODUCT(--(Sheet1!$B$2:$B$6000=$A2),--(Sheet1!$C$2:$C$6000>4))

Copy this range B2:E2 all the way down

message
(e-mail address removed)...
 
B

Bob Phillips

I think SUMPRODUCT gets what you want

=SUMPRODUCT(--($B2:$B200=1234),--($C$2:$C$200>=2),--($C$2:$C$200<3))

which gives the sum of book 1234 betwwen 2-3 hours. Extend that over a
table, and you can then pivot the results.

--

HTH

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

swjtx

Hi and Thanks to both of you!

Sumproduct worked. I was looking at that but the arrays were seperated
by an * in the examples I found. I noticed you used "--".

One tiny problem remains. As I drag the formula down the page, it
correctly selects the next book# but it also increment the range
searched on the first sheet. Any way to make it choose the same range
without manually editing?

Example:
First Formula:
=SUMPRODUCT(--(Sheet1!$C2:$C200=$A2),--(Sheet1!$C2:$C200>=2),--(Sheet1!$C2:$C200<3))

Second Formula:

=SUMPRODUCT(--(Sheet1!$C3:$C201=$A3),--(Sheet1!$C3:$C201>=2),--(Sheet1!$C3:$C201<3))

I want it to choose $A3 but I want it to search the same range
(C2:C200), not increment. Any way to do this?
 
D

Dave Peterson

Use $c$2:$c$200

The $ signs mean not to adjust the range when you copy the formula.
 
B

Bob Phillips

Use

=SUMPRODUCT(--(Sheet1!$C$2:$C$200=$A2),--(Sheet1!$C$2:$C$200>=2),--(Sheet1!$
C$2:$C$200<3))


--

HTH

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

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