ExcelBanter

ExcelBanter (https://www.excelbanter.com/)
-   Excel Discussion (Misc queries) (https://www.excelbanter.com/excel-discussion-misc-queries/)
-   -   Match, Index (https://www.excelbanter.com/excel-discussion-misc-queries/220706-match-index.html)

Shortstopper00

Match, Index
 
I need a formula for set of data. The user picks to options and from a chart
I need the number brought back. Example

Norway Maple Yes 9.5
Red Maple Yes 15
Silver Maple Yes 19
Norway Maple No 9.5
Red Maple No 15
Silver Maple No 19

I user would put in red maple and no...and 15 would be brought back. I was
using the code
=INDEX(N3:N48,MATCH(Ctree,L3:L48,0),MATCH(CLeaf,M3 :M48,0))

Ctree = type of tree
Cleaf = yes or no

Now it would bring the answer back for any values with Yes but nothing for
No's. There was a reference error....Any Suggestions


Dave Peterson

Match, Index
 
If you want to bring back the data from the first match:

Saved from a previous post:

If you want exact matches for just two columns (and return a value from a
third), you could use:

=index(othersheet!$c$1:$c$100,
match(1,(a2=othersheet!$a$1:$a$100)
*(b2=othersheet!$b$1:$b$100),0))

(all in one cell)

This is an array formula. Hit ctrl-shift-enter instead of enter. If you do it
correctly, excel will wrap curly brackets {} around your formula. (don't type
them yourself.)

Adjust the range to match--but you can only use the whole column in xl2007.

This returns the value in othersheet column C when column A and B (of
othersheet) match A2 and B2 of the sheet with the formula.

And you can add more conditions by just adding more stuff to that product
portion of the formula:

=index(othersheet!$d$1:$d$100,
match(1,(a2=othersheet!$a$1:$a$100)
*(b2=othersheet!$b$1:$b$100)
*(c2=othersheet!$c$1:$c$100),0))

============
If there is only one match and you're bringing back a number, you can use:

=sumproduct(--(othersheet!a1:a10=ctree),
--(othersheet!b1:b10=cleaf),
(othersheet!c1:c10))

Adjust the ranges to match--but you can't use whole columns (except in xl2007).

=sumproduct() likes to work with numbers. The -- stuff changes trues and falses
to 1's and 0's.

Bob Phillips explains =sumproduct() in much more detail he
http://www.xldynamic.com/source/xld.SUMPRODUCT.html

And J.E. McGimpsey has some notes at:
http://mcgimpsey.com/excel/formulae/doubleneg.html

Shortstopper00 wrote:

I need a formula for set of data. The user picks to options and from a chart
I need the number brought back. Example

Norway Maple Yes 9.5
Red Maple Yes 15
Silver Maple Yes 19
Norway Maple No 9.5
Red Maple No 15
Silver Maple No 19

I user would put in red maple and no...and 15 would be brought back. I was
using the code
=INDEX(N3:N48,MATCH(Ctree,L3:L48,0),MATCH(CLeaf,M3 :M48,0))

Ctree = type of tree
Cleaf = yes or no

Now it would bring the answer back for any values with Yes but nothing for
No's. There was a reference error....Any Suggestions


--

Dave Peterson


All times are GMT +1. The time now is 03:44 PM.

Powered by vBulletin® Copyright ©2000 - 2025, Jelsoft Enterprises Ltd.
ExcelBanter.com