ExcelBanter

ExcelBanter (https://www.excelbanter.com/)
-   Excel Worksheet Functions (https://www.excelbanter.com/excel-worksheet-functions/)
-   -   lookup multi values (https://www.excelbanter.com/excel-worksheet-functions/107007-lookup-multi-values.html)

robtlewis957

lookup multi values
 
I need to lookup data within a list and select a value in the appropriate row
based on the values of two inputs(report date and user name, for example),
not just one. The list data is such that I cannot make any modifications to
it (like concatenating the two fields together.
ReportDate User Value
060824 Mary $5
060824 Joe $4
060831 Mary $6
060831 Joe $3
I need to be able to retrieve the value $3 by inputting 060831 and Joe.
Note the list has many rows and about a dozen columns.

Dave Peterson

lookup multi values
 
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)

Where A2 holds the the value to match in column A and B2 holds the value to
match in column B.

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't use the whole column.

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))

robtlewis957 wrote:

I need to lookup data within a list and select a value in the appropriate row
based on the values of two inputs(report date and user name, for example),
not just one. The list data is such that I cannot make any modifications to
it (like concatenating the two fields together.
ReportDate User Value
060824 Mary $5
060824 Joe $4
060831 Mary $6
060831 Joe $3
I need to be able to retrieve the value $3 by inputting 060831 and Joe.
Note the list has many rows and about a dozen columns.


--

Dave Peterson

Biff

lookup multi values
 
Hi!

If there will be only a single instance of 060831 and Joe?

Assuming the report dates are really formatted TEXT entries (leading 0's):

=SUMPRODUCT(--(A2:A5="060831"),--(B2:B5="Joe"),C2:C5)

If there might be multiple instances of 060831 and Joe which one do you
want?

Entered as an array using the key combination of CTRL,SHIFT,ENTER (not just
ENTER):

=INDEX(C2:C5,MATCH(1,(A2:A5="060831")*(B2:B5="Joe" ),0))

Will match the FIRST instance.

Biff

"robtlewis957" wrote in message
...
I need to lookup data within a list and select a value in the appropriate
row
based on the values of two inputs(report date and user name, for example),
not just one. The list data is such that I cannot make any modifications
to
it (like concatenating the two fields together.
ReportDate User Value
060824 Mary $5
060824 Joe $4
060831 Mary $6
060831 Joe $3
I need to be able to retrieve the value $3 by inputting 060831 and Joe.
Note the list has many rows and about a dozen columns.





All times are GMT +1. The time now is 07:37 PM.

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