This will test you!!

B

Blaknight

Hello All,

My first post here as i am very stuck with a very complex formula.

-=See attachment=-

Please if you can help grab the attachment so you know what i am o
about.

This is my problem. I have 6 columns of data labeled
- Item, Date, Qty, Quality, Action, Charater.

What i want is the formula to search A11 to F41 (F41 will be greate
with more data entered) for a word in column A say *Medium Leather
then look for the value in column C of that word found in column A an
continue.

I have achieved this but when it has found the 1st word it doesn'
continue on to find another word of the same. This is what i hav
used.

=VLOOKUP("Medium Leather",A11:F41,3,)

Then on top of that i want it to look in column E for one of two words
Deposit and Withdrawn. I want the formula to add the data found i
column C when the word Deposit has been found in column E, an
subtracted if the word Withdrawn has been found.

This infomation needs to be placed in the Qty column in the *Total
Table* next to the corresponding Item.

So. basically i want

- Search Entire *Data Table* A - F, 11 - ** for Item
- Get value in C
- Work out if C value is - or + from E (Deposit = +, Withdrawn = -)
- Get current total value sum in I

I think you could only iunderstand if you download the attachment.

Thanks in advanced.

Blaknigh

+-------------------------------------------------------------------
|Filename: help_sKsLeather Blotter.zip
|Download: http://www.excelforum.com/attachment.php?postid=3836
+-------------------------------------------------------------------
 
P

PY & Associates

vlookup only locate the first occurrence of the target. It cannot look
beyond for the 2nd occurrence.

try use find method,
use find (from here) in the 2nd loop
stop loop when list exhausts.
 
M

Max

One way ..

H12:H24 (except H18) contains the lookup items:

Medium Leather
Heavy Leather
Thick Leather
Rugged Leather
etc

Put in I12:

=SUMPRODUCT(($A$11:$A$100=H12)*($E$11:$E$100="Deposit"),
$C$11:$C$100)-SUMPRODUCT(($A$11:$A$100=H12)
*($E$11:$E$100="Withdrawn"),$C$11:$C$100)

Copy I12 down to I24

(Clean up by deleting the formula in I18
for the header in H18 where it doesn't apply)

Adapt the ranges to suit, but note that we can't use
entire column references in SUMPRODUCT
 
B

Blaknight

AWESOME!!! Thankyou so very much.. I got it working. I cant believe i
actualy works.
 
M

Max

Blaknight said:
.. I cant believe it actualy works..

... and I can't believe why the SUMPRODUCT suggestion
didn't work for you. Testing here was fine ..
(btw, you had a typo error in H12, missing "t" in "Leather")
 

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