ExcelBanter

ExcelBanter (https://www.excelbanter.com/)
-   Excel Discussion (Misc queries) (https://www.excelbanter.com/excel-discussion-misc-queries/)
-   -   Index Match Function Question (https://www.excelbanter.com/excel-discussion-misc-queries/112888-index-match-function-question.html)

excelnewbie44

Index Match Function Question
 
I have a large database set up with information in cells A-G. Cells A-D
contain unique information and I would like to create a function that will
find when the criteria matches these four cells it pulls in the answer in the
7th cell (G). I hope this makes sense. I tried to set up a INDEX-MATCH
function but have been unsuccessful so far. Is this the right function to
use? If so, do you know the general format I should be using to set this up?

JMB

Index Match Function Question
 
Assuming your database is in A1:G100, criteria are in cell1, cell2, cell3,
cell4, try:

=INDEX(G1:G100, MATCH(cell1&cell2&cell3&cell4,
A1:A100&B1:B100&C1:C100&D1:D100, 0))

entered w/Cntrl+Shift+Enter or you'll get #VALUE!

Alternatively, insert a column in your data (lets say column A - so
everything shifts one column to the right) and concatenate the four columns
you are using as a lookup
=B1&C1&D1&E1

copy it down your table, then use VLOOKUP
=VLOOKUP(cell1&cell2&cell3&cell4, A1:H100, 8, 0)


"excelnewbie44" wrote:

I have a large database set up with information in cells A-G. Cells A-D
contain unique information and I would like to create a function that will
find when the criteria matches these four cells it pulls in the answer in the
7th cell (G). I hope this makes sense. I tried to set up a INDEX-MATCH
function but have been unsuccessful so far. Is this the right function to
use? If so, do you know the general format I should be using to set this up?


excelnewbie44

Index Match Function Question
 
After reading over this again it seems a little confusing. I want to create a
function that looks at the cells A to D. If it can find a match to the given
criteria, I want it to pull the answer in cell G of that row and put that in
for the answer. I hope this clarifies. Any help would be great.

"excelnewbie44" wrote:

I have a large database set up with information in cells A-G. Cells A-D
contain unique information and I would like to create a function that will
find when the criteria matches these four cells it pulls in the answer in the
7th cell (G). I hope this makes sense. I tried to set up a INDEX-MATCH
function but have been unsuccessful so far. Is this the right function to
use? If so, do you know the general format I should be using to set this up?


excelnewbie44

Index Match Function Question
 
Thank you very much, that worked!

"JMB" wrote:

Assuming your database is in A1:G100, criteria are in cell1, cell2, cell3,
cell4, try:

=INDEX(G1:G100, MATCH(cell1&cell2&cell3&cell4,
A1:A100&B1:B100&C1:C100&D1:D100, 0))

entered w/Cntrl+Shift+Enter or you'll get #VALUE!

Alternatively, insert a column in your data (lets say column A - so
everything shifts one column to the right) and concatenate the four columns
you are using as a lookup
=B1&C1&D1&E1

copy it down your table, then use VLOOKUP
=VLOOKUP(cell1&cell2&cell3&cell4, A1:H100, 8, 0)


"excelnewbie44" wrote:

I have a large database set up with information in cells A-G. Cells A-D
contain unique information and I would like to create a function that will
find when the criteria matches these four cells it pulls in the answer in the
7th cell (G). I hope this makes sense. I tried to set up a INDEX-MATCH
function but have been unsuccessful so far. Is this the right function to
use? If so, do you know the general format I should be using to set this up?


Dave Peterson

Index Match Function Question
 
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'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))

==============
So your array formula would look like:

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



excelnewbie44 wrote:

I have a large database set up with information in cells A-G. Cells A-D
contain unique information and I would like to create a function that will
find when the criteria matches these four cells it pulls in the answer in the
7th cell (G). I hope this makes sense. I tried to set up a INDEX-MATCH
function but have been unsuccessful so far. Is this the right function to
use? If so, do you know the general format I should be using to set this up?


--

Dave Peterson


All times are GMT +1. The time now is 06:50 PM.

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