Index/ Match/ Lookup

oO P2K Oo

New Member
Joined
Aug 12, 2018
Messages
25
Office Version
  1. 365
Platform
  1. Windows
Hi All,

Thank you for viewing my post.

I am having difficulty with the index/match function.

Below is an extract of my table (I had issues uploading the table via the normal channels).

ABCDEFG
1Local codeAgeUniversal CodeLocal CodeAge BoundaryUniversal Code
2TUCEG3TUCEG6ABC51A
3TUCEG5TUCEG19ABC51B
4TUCEG19TUCEG19+ABC51C
5TUCEG20
6TUCEG6
7TUCEG12
8TUCEG21
9TUCEG17
10TUCEG24
11TUCEG67
12TUCEG38
13TUCEG0

<tbody>
</tbody>

The age boundary simply refers to the age in column B, if someone is 0-5 years and 364 days old they should be given a code ABC51A. If a person is 6-18 years and 364 days old they should be given a Universal code ABC51B. anyone above 19 years of age will have the code ABC51C. I can use the match function to identify the Local code, but I am struggling to link it with the age.

Can anyone help me with this issue? Many thanks in advance for your assistance with this query.

If you require any further explanations then please ask.
 

Excel Facts

Create a chart in one keystroke
Select the data and press Alt+F1 to insert a default chart. You can change the default chart to any chart type
In C2:

=INDEX($G$2:$G$4,MATCH(1,IF($E$2:$E$4=A2,IF($F$2:$F$4=MIN(IF($E$2:$E$4=A2,IF(B2<=$F$2:$F$4,$F$2:$F$4))),1)),0))

Enter CTRL-SHIFT-ENTER.

You will need to change 19+ to a number eg 100.
 
Upvote 0

Book1
ABCDEFG
1Local codeAgeUniversal CodeLocal CodeAge BoundaryUniversal Code
2TUCEG3ABC51ATUCEG6ABC51A
3TUCEG5ABC51ATUCEG19ABC51B
4TUCEG19ABC51CTUCEG19ABC51C
5TUCEG20ABC51C
6TUCEG6ABC51A
7TUCEG12ABC51A
8TUCEG21ABC51C
9TUCEG17ABC51A
10TUCEG24ABC51C
11TUCEG67ABC51C
12TUCEG38ABC51C
13TUCEG0ABC51A
Sheet1


Note that + in F4 is removed.

In C2 enter and copy down:

=LOOKUP(MAX(B2,MIN($F$2:$F$4)),$F$2:$F$4,$G$2:$G$4)

provided that the local code is relevant or F2:G4 is the table for TUCEG.
 
Upvote 0
Hi Aladin,

The answer is great, however, if the Local code changes, then the Universal code won't be correct. Apologies, for not giving all the local codes. I just wanted to keep it simple :(
 
Upvote 0
Thank you Steve, this has worked brilliantly. Thank you very much.
 
Upvote 0
Hi Aladin,

The answer is great, however, if the Local code changes, then the Universal code won't be correct. Apologies, for not giving all the local codes. I just wanted to keep it simple :(

You can name your tables in terms of the codes involded. If you that, you can have:

=LOOKUP(MAX(B2,MIN(INDEX(INDIRECT(A2),0,1))),INDIRECT(A2))
 
Upvote 0

Forum statistics

Threads
1,215,463
Messages
6,124,965
Members
449,201
Latest member
Jamil ahmed

We've detected that you are using an adblocker.

We have a great community of people providing Excel help here, but the hosting costs are enormous. You can help keep this site running by allowing ads on MrExcel.com.
Allow Ads at MrExcel

Which adblocker are you using?

Disable AdBlock

Follow these easy steps to disable AdBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the icon in the browser’s toolbar.
2)Click on the "Pause on this site" option.
Go back

Disable AdBlock Plus

Follow these easy steps to disable AdBlock Plus

1)Click on the icon in the browser’s toolbar.
2)Click on the toggle to disable it for "mrexcel.com".
Go back

Disable uBlock Origin

Follow these easy steps to disable uBlock Origin

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back

Disable uBlock

Follow these easy steps to disable uBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back
Back
Top