Conflict with

erutherford

Active Member
Joined
Dec 19, 2016
Messages
453
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???
 

Excel Facts

Waterfall charts in Excel?
Office 365 customers have access to Waterfall charts since late 2016. They were added to Excel 2019.
See if this example helps


[Table="class: grid"][tr][td="bgcolor: #DCE6F1"][/td][td="bgcolor: #DCE6F1"]
A
[/td][td="bgcolor: #DCE6F1"]
B
[/td][td="bgcolor: #DCE6F1"]
C
[/td][td="bgcolor: #DCE6F1"]
D
[/td][td="bgcolor: #DCE6F1"]
E
[/td][td="bgcolor: #DCE6F1"]
F
[/td][td="bgcolor: #DCE6F1"]
G
[/td][td="bgcolor: #DCE6F1"]
H
[/td][/tr]
[tr][td="bgcolor: #DCE6F1"]
1
[/td][td]
Name​
[/td][td]
Div​
[/td][td]
Model​
[/td][td]
Pts​
[/td][td][/td][td]
Division​
[/td][td]
Model​
[/td][td]
Name?​
[/td][/tr]

[tr][td="bgcolor: #DCE6F1"]
2
[/td][td]
Name1​
[/td][td]
Div1​
[/td][td]
M1​
[/td][td="bgcolor:#FFFF00"]
10​
[/td][td][/td][td]
Div1​
[/td][td]
M1​
[/td][td]
Name1​
[/td][/tr]

[tr][td="bgcolor: #DCE6F1"]
3
[/td][td]
Name2​
[/td][td]
Div1​
[/td][td]
M1​
[/td][td]
8​
[/td][td][/td][td]
Div2​
[/td][td]
M2​
[/td][td]
Name5​
[/td][/tr]

[tr][td="bgcolor: #DCE6F1"]
4
[/td][td]
Name3​
[/td][td]
Div1​
[/td][td]
M1​
[/td][td]
9​
[/td][td][/td][td][/td][td][/td][td][/td][/tr]

[tr][td="bgcolor: #DCE6F1"]
5
[/td][td]
Name4​
[/td][td]
Div2​
[/td][td]
M2​
[/td][td]
9​
[/td][td][/td][td][/td][td][/td][td][/td][/tr]

[tr][td="bgcolor: #DCE6F1"]
6
[/td][td]
Name5​
[/td][td]
Div2​
[/td][td]
M2​
[/td][td="bgcolor:#DCE6F1"]
10​
[/td][td][/td][td][/td][td][/td][td][/td][/tr]

[tr][td="bgcolor: #DCE6F1"]
7
[/td][td]
Name6​
[/td][td]
Div2​
[/td][td]
M2​
[/td][td]
8​
[/td][td][/td][td][/td][td][/td][td][/td][/tr]
[/table]


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.
 
Upvote 0
Thank you very much! I thought this was going to be difficult to explain and very little response. You nailed it!
 
Upvote 0
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>
 
Upvote 0
Something like this


[Table="class: grid"][tr][td="bgcolor: #DCE6F1"][/td][td="bgcolor: #DCE6F1"]
A
[/td][td="bgcolor: #DCE6F1"]
B
[/td][td="bgcolor: #DCE6F1"]
C
[/td][td="bgcolor: #DCE6F1"]
D
[/td][td="bgcolor: #DCE6F1"]
E
[/td][td="bgcolor: #DCE6F1"]
F
[/td][td="bgcolor: #DCE6F1"]
G
[/td][td="bgcolor: #DCE6F1"]
H
[/td][/tr]
[tr][td="bgcolor: #DCE6F1"]
1
[/td][td]
Name​
[/td][td]
Div​
[/td][td]
Model​
[/td][td]
Pts​
[/td][td][/td][td]
Division​
[/td][td]
Model​
[/td][td]
Name?​
[/td][/tr]

[tr][td="bgcolor: #DCE6F1"]
2
[/td][td]
Name1​
[/td][td]
Div1​
[/td][td]
M1​
[/td][td="bgcolor:#FFFF00"]
10​
[/td][td][/td][td]
Div1​
[/td][td]
M1​
[/td][td="bgcolor:#FFFF00"]
Name1​
[/td][/tr]

[tr][td="bgcolor: #DCE6F1"]
3
[/td][td]
Name2​
[/td][td]
Div1​
[/td][td]
M1​
[/td][td]
8​
[/td][td][/td][td]
Div2​
[/td][td]
M2​
[/td][td="bgcolor:#DCE6F1"]
Name5​
[/td][/tr]

[tr][td="bgcolor: #DCE6F1"]
4
[/td][td]
Name3​
[/td][td]
Div1​
[/td][td]
M1​
[/td][td="bgcolor:#D8E4BC"]
9​
[/td][td][/td][td][/td][td][/td][td][/td][/tr]

[tr][td="bgcolor: #DCE6F1"]
5
[/td][td]
Name4​
[/td][td]
Div2​
[/td][td]
M2​
[/td][td="bgcolor:#E6B8B7"]
9​
[/td][td][/td][td]
Second Largest​
[/td][td][/td][td][/td][/tr]

[tr][td="bgcolor: #DCE6F1"]
6
[/td][td]
Name5​
[/td][td]
Div2​
[/td][td]
M2​
[/td][td="bgcolor:#DCE6F1"]
10​
[/td][td][/td][td]
Div1​
[/td][td]
M1​
[/td][td="bgcolor:#D8E4BC"]
Name3​
[/td][/tr]

[tr][td="bgcolor: #DCE6F1"]
7
[/td][td]
Name6​
[/td][td]
Div2​
[/td][td]
M2​
[/td][td]
8​
[/td][td][/td][td]
Div2​
[/td][td]
M2​
[/td][td="bgcolor:#E6B8B7"]
Name4​
[/td][/tr]

[tr][td="bgcolor: #DCE6F1"]
8
[/td][td][/td][td][/td][td][/td][td][/td][td][/td][td][/td][td][/td][td][/td][/tr]
[/table]


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.
 
Upvote 0

Forum statistics

Threads
1,223,164
Messages
6,170,444
Members
452,326
Latest member
johnshaji

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