Make min/max formulas read concatenated data?

Elihue

New Member
Joined
Aug 16, 2016
Messages
21
Hi everyone,

How would I go about using min/max formulas with concatenated data? For example...

I have two or more cells that are concatenated and I want to use min/max on formulas on them. There will be text as well as numerical values. "Owners" which would be text and and a "height" which would be numerical. I want the min/max formula to only work on a certain portion of the numerical data in the concatenated cell.


Cell 1 (Concatenated) Cell 2 (Concatenated) Output Cell (Returns the data with the minimum number along with it's corresponding owner info) (If using min formula)
IPL, 21.33 DGL, 25.42 IPL, 21.33


The purpose of this is because I want the formula to bring the owner information along with it so you don't need to sift though tons of data to look for that number and find it's corresponding owner.
 
Last edited:

Excel Facts

Wildcard in VLOOKUP
Use =VLOOKUP("Apple*" to find apple, Apple, or applesauce
That's not a good idea. Basic design philosophy states that there should be 1 piece of data per cell. When you put 2 pieces of data per cell, you can't use standard formulas, or formatting, or searching, and it gets really complicated, far worse than not finding the matching cell. You can group data together very easily with good design. Even better, build a table.

This formula:

<mid(b1,find(",",b1)+1,99)+0,a1,b1)
=IF(MID(A1,FIND(",",A1)+1,99)+0< MID(B1,FIND(",",B1)+1,99)+0,A1,B1)

pretty much does what you ask, but it's long, complicated, and doesn't scale well at all.</mid(b1,find(",",b1)+1,99)+0,a1,b1)
 
Last edited:
Upvote 0
Ok, how would I do the equivalent with a table?

For example, I have a table on one tab with my data. Then I have another table in a separate tab where I am condensing the data to be useful. On table #1 I have a group of data I want to sift through using a max formula. It's got 10 Pairs of data on it. Comm Owner 1, Comm height 1, Comm Owner 2, Comm Height 2, Comm Owner 3, Comm Height 3, continuing on until it gets to 10. On table #2 I'm trying to use a max formula to return the highest value of all of those previously mentioned pairs into one column. But I would like to somehow retain the owner as well. Could I have that show up in an adjacent column? The problem is, the max value could be anywhere in those 10 pairs of data. All the owners could have duplicates as well.
 
Last edited:
Upvote 0
Sure, you could do something like this:

BCDEFGHI
1OwnerHeightOwnerHeightOwnerHeight
2One21.1Two32.2Two32.2
3Two32.2Six32.2
4Three8One21.1
5Four9.1Seven21.1
6Five18.1Ten21.1
7Six32.2Five18.1
8Seven21.1Nine17
9Eight8Four9.1
10Nine17Three8
11Ten21.1Eight8

<tbody>
</tbody>
Sheet6

Worksheet Formulas
CellFormula
E2=INDEX(MyTable[Owner],MATCH(F2,MyTable[Height],0))
F2=MAX(MyTable[Height])
I2=LARGE(MyTable[Height],ROWS($I$2:$I2))

<tbody>
</tbody>

<tbody>
</tbody>

Array Formulas
CellFormula
H2{=INDEX(MyTable[Owner],SMALL(IF(MyTable[Height]=I2,ROW(MyTable[Height])-ROW(INDEX(MyTable[Height],1))+1),COUNTIF($I$2:$I2,I2)))}

<tbody>
</tbody>
Entered with Ctrl+Shift+Enter. If entered correctly, Excel will surround with curly braces {}.
Note: Do not try and enter the {} manually yourself

<tbody>
</tbody>

<tbody>
</tbody>


B2:C11 I defined a table named MyTable (which could be on another sheet).

If you only want the top score/owner, you could use the formulas in E2:F2. If you want to have a list of the top 3, top 5, or whatever, and make sure to handle duplicate values, you could use the H2:I2 formulas.
 
Last edited:
Upvote 0

Forum statistics

Threads
1,213,561
Messages
6,114,315
Members
448,564
Latest member
ED38

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