Forum Discussion
How to use LOOKUP to refer to tables related to specific ranges of values in a nominated cell
- Mar 09, 2019
Hello Alcesterman ,
In the attached file, I modified K27, V30, AB30, AH30, and AN30 from 40+ to 41. The formula in F16, copied across to I16, is:
=INDEX(($V9:$Z30,$AB9:$AF30,$AH9:$AL30,$AN9:$AR30),
MATCH(F14,CHOOSE(SUM(F8>0,F8>24,F8>25,F8>32),$V9:$V30,$AB9:$AB30,$AH9:$AH30,$AN9:$AN30),1),
COLUMN(B1),SUM(F8>0,F8>24,F8>25,F8>32))Cheers!
Twifoo
Just in case a non-standard approach is of interest. I rely entirely upon defined names and never use the standard cell referencing by location. My first step would be to build a defined name 'case' that will indicate which table A-D is to be to used for subsequent lookups.
The definition of 'case'
= 2 + SIGN( combinedHCP-25)+ ( combinedHCP>32)
is a bit of a dog but it sets the scene for the named reference 'table' that is defined by
= CHOOSE( case, tableA, tableB, tableC, tableD )
From there on, one can ignore the fact that 4 tables are involved and simple build the lookup formula as if 'table' were a straightforward range reference. Individual column names can be defined to refer to
= INDEX( table, 0, 1 )
etc. as required.
- PeterBartholomew1Mar 09, 2019Silver Contributor
I did implement a solution but I had overlooked the fact that your longest suit length etc. changed as the vulnerability or contract suit changed across the columns.
- AlcestermanMar 13, 2019Copper ContributorMany thanks. Twifoo gave me the solution.
- TwifooMar 05, 2019Silver ContributorI find it difficult to decipher the applicable formula for you. Please attach your sample Excel file.
- AlcestermanMar 08, 2019Copper Contributor
file dropbox link:
https://www.dropbox.com/s/5at72u390w3b7th/PAR%20BRIDGE%20-%20PAR%20SCORE%20CALCULATOR%201909.xlsx?dl=0
As I said, which table is referred to depends on the value in cell row 8 (f,g,h or i)
If the value in cell f8, g8, h8 or i8 is <25 , table A should be used to look up from the corresponding value for row 14 (f to i)
If = 25, then Table B
If in range 26 - 32, then Table C
and if greater or equal to 33, then table D
The choice of which column is used (f, g, h or i) is determined by the user (according to the final Bridge contract and the Bridge vulnerability)
The values in Rows 6, 7, 10 and 12 are entered by the user. Excel determines the 'Par Value' in 16.
the User enters the actual score in 18
Excel calculates the Net score and Looks up the IMPs (Internnational Match Points) equivalent by LOOKUP in Table E
Simple concept! Not so simple to set up to work automatically. I like an intellectual challenge and appreciate the help I am getting.
Alf
- TwifooMar 09, 2019Silver Contributor
Hello Alcesterman ,
In the attached file, I modified K27, V30, AB30, AH30, and AN30 from 40+ to 41. The formula in F16, copied across to I16, is:
=INDEX(($V9:$Z30,$AB9:$AF30,$AH9:$AL30,$AN9:$AR30),
MATCH(F14,CHOOSE(SUM(F8>0,F8>24,F8>25,F8>32),$V9:$V30,$AB9:$AB30,$AH9:$AH30,$AN9:$AN30),1),
COLUMN(B1),SUM(F8>0,F8>24,F8>25,F8>32))Cheers!
Twifoo