Conflict with

erutherford

Active Member
Joined
Dec 19, 2016
Messages
320
This might be difficult to explain, but I'll give it a shot.

Basic overview is a table where numerical scores are entered. The scores are ranked 1, 2, and 3 based on the "Div" (Division) and the Model of the car.


DIV is located in A68 and Model is Located in A67.

The code below is for first place (highest score ("Pts") So it returns the highest score and also pulls in the "FName". Same formula for LName etc.

<code>
=IFERROR(INDEX(FName,MATCH(MAX(IF(Div=A68,Pts)*(Model=A67)),Pts,0)),"x")
</code>


Here is the second line of code that its in conflict with the code above.

<code>
=IFERROR(INDEX(LName,MATCH(MAX(IF(Div=A75,Pts)*(Model=A74)),Pts,0)),"x")
</code>

Its DIV is located in A75 and Model is Located in A74.

If both cars receive the identical score, even though they are in different DIV, excel display the same name in both categories. Break the tie and it displays correctly.

Clear as mud???
 

Marcelo Branco

MrExcel MVP
Joined
Aug 23, 2010
Messages
16,344
See if this example helps


A
B
C
D
E
F
G
H
1
Name​
Div​
Model​
Pts​
Division​
Model​
Name?​
2
Name1​
Div1​
M1​
10​
Div1​
M1​
Name1​
3
Name2​
Div1​
M1​
8​
Div2​
M2​
Name5​
4
Name3​
Div1​
M1​
9​
5
Name4​
Div2​
M2​
9​
6
Name5​
Div2​
M2​
10​
7
Name6​
Div2​
M2​
8​

Array formula in H2 copied down
=INDEX(Name,MATCH(MAX(IF(Div=F2,IF(Model=G2,Pts))),IF(Div=F2,IF(Model=G2,Pts)),0))
Ctrl+Shift+Enter

Observe the part in red. Instead of just Pts the formula uses IF(Div=F2,IF(Model=G2,Pts)) as the lookup_array

M.
 

erutherford

Active Member
Joined
Dec 19, 2016
Messages
320
Thank you very much! I thought this was going to be difficult to explain and very little response. You nailed it!
 

erutherford

Active Member
Joined
Dec 19, 2016
Messages
320
Can the same be applied to 2nd and third place code?

<code>
=IFERROR(INDEX(Entry,MATCH(LARGE(IF(Div=A68,Pts)*(Model=A67),2),Pts,0)),"x")
</code>

I modified it, but get a "to few augment error"

<code>
=INDEX(Entry,MATCH(LARGE(IF(Div=A68,IF(Model=A67,Pts))),IF(Div=A68,IF(Model=A67,Pts)),0))
</code>
 

Marcelo Branco

MrExcel MVP
Joined
Aug 23, 2010
Messages
16,344
Something like this


A
B
C
D
E
F
G
H
1
Name​
Div​
Model​
Pts​
Division​
Model​
Name?​
2
Name1​
Div1​
M1​
10​
Div1​
M1​
Name1​
3
Name2​
Div1​
M1​
8​
Div2​
M2​
Name5​
4
Name3​
Div1​
M1​
9​
5
Name4​
Div2​
M2​
9​
Second Largest​
6
Name5​
Div2​
M2​
10​
Div1​
M1​
Name3​
7
Name6​
Div2​
M2​
8​
Div2​
M2​
Name4​
8

Array Formula in H6 copied down
=INDEX(Name,MATCH(LARGE(IF(Div=F6,IF(Model=G6,Pts)),2),IF(Div=F6,IF(Model=G6,Pts)),0))
Ctrl+Shift+Enter

M.
 

erutherford

Active Member
Joined
Dec 19, 2016
Messages
320
forgot the "2"!

Works perfect.

I read up on the diff between =index and Iferror

thanks this was a huge help!
 

Forum statistics

Threads
1,086,097
Messages
5,387,812
Members
402,081
Latest member
PiotrX

Some videos you may like

This Week's Hot Topics

Top