Multiple Values in Single Cell: How can I apply formulas?

Pulsar3000

New Member
Joined
Apr 19, 2021
Messages
44
Office Version
  1. 365
Platform
  1. Windows
Hello Excel Gurus!

Here's what's going on. I'm dealing with regular and overtime hourly rates.

The item after the bolded word function below yields results in a single cell as shown in the yellow cell of my image. Since multiple values are in a single cell, the cell is text. I know the Value function, multiplying by 1 or adding a 0 can fix the number saved as text to an individual number so some version of this I presume will be imbedded in the potential solution.

Question: Can the gold and blue box be accomplished strictly using some function(s) in cells Z2 and AA2 not involving VBA or Text to Columns?

1619242637870.png


Function: T2=(IF(OR(R2="OT Hours",R2="Holiday Hours")=TRUE,TEXTJOIN(", ",TRUE,UNIQUE(IF(($A$2:$A$16=A2)*($D$2:$D$16=D2)*($F$2:$F$16=F2)*(@$I$2:$I$16=I2)*($K$2:$K$16<>0),$N$2:$N$16,""))),0))

Functions/Descriptions of Cells Referenced in Above Function:
R2=INDEX($K$1:$M$1,MATCH(TRUE,INDEX(K4:M4<>0,),0))
A2=Name of place that is just text
D2=Name of person that is just text
F2=INDEX(Type!$B$2:$B$45,MATCH(E2,Type!$A$2:$A$45,0))
I2=INDEX(Rates!$C$2:$C$6,MATCH(1,((Rates!$B$2:$B$6=A2)*(Rates!$C$2:$C$6<=G2)*(Rates!$D$2:$D$6>=G2)),0))
K2=Amount of Hours hardcoded
N2=Rate hardcoded
 

Excel Facts

Whats the difference between CONCAT and CONCATENATE?
The newer CONCAT function can reference a range of cells. =CONCATENATE(A1,A2,A3,A4,A5) becomes =CONCAT(A1:A5)
if always you have three number at column T try this:
Book1.xlsm
ANOTYZAAAB
14570, 30, 40301.5
25070, 25, 55252
36030, 35, 40302
4200150, 100, 1201002
5120100, 90, 80801.5
6
7
Sheet2
Cell Formulas
RangeFormula
Z1:Z5Z1=IF(OR(N1/LEFT(T1,FIND(",",T1)-1)=1.5,N1/LEFT(T1,FIND(",",T1)-1)=2),LEFT(T1,FIND(",",T1)-1),IF(OR(N1/TRIM(MID(T1,FIND(",",T1)+1,LEN(T1)-FIND(",",T1,FIND(",",T1)+1)))=1.5,N1/TRIM(MID(T1,FIND(",",T1)+1,LEN(T1)-FIND(",",T1,FIND(",",T1)+1)))=2),TRIM(MID(T1,FIND(",",T1)+1,LEN(T1)-FIND(",",T1,FIND(",",T1)+1))),IF(OR(N1/RIGHT(T1,LEN(T1)-LEN(SUBSTITUTE(T1,",","")))=1.5,N1/RIGHT(T1,LEN(T1)-LEN(SUBSTITUTE(T1,",","")))=2),RIGHT(T1,LEN(T1)-LEN(SUBSTITUTE(T1,",",""))),"")))
AA1:AA5AA1=N1/Z1
 
Upvote 0
if always you have three number at column T try this:
Book1.xlsm
ANOTYZAAAB
14570, 30, 40301.5
25070, 25, 55252
36030, 35, 40302
4200150, 100, 1201002
5120100, 90, 80801.5
6
7
Sheet2
Cell Formulas
RangeFormula
Z1:Z5Z1=IF(OR(N1/LEFT(T1,FIND(",",T1)-1)=1.5,N1/LEFT(T1,FIND(",",T1)-1)=2),LEFT(T1,FIND(",",T1)-1),IF(OR(N1/TRIM(MID(T1,FIND(",",T1)+1,LEN(T1)-FIND(",",T1,FIND(",",T1)+1)))=1.5,N1/TRIM(MID(T1,FIND(",",T1)+1,LEN(T1)-FIND(",",T1,FIND(",",T1)+1)))=2),TRIM(MID(T1,FIND(",",T1)+1,LEN(T1)-FIND(",",T1,FIND(",",T1)+1))),IF(OR(N1/RIGHT(T1,LEN(T1)-LEN(SUBSTITUTE(T1,",","")))=1.5,N1/RIGHT(T1,LEN(T1)-LEN(SUBSTITUTE(T1,",","")))=2),RIGHT(T1,LEN(T1)-LEN(SUBSTITUTE(T1,",",""))),"")))
AA1:AA5AA1=N1/Z1
@maabadi

Thanks so much!!

Unfortunately, I don't know if I'll have 2, 3 or 10 values. If your solution is any indication, we may have to just do these manually since that's quite the nested function just for three values!

It is a thing of beauty though :)

I was curious. Item 3 in your example actually has two values that meet the test.

Cell N3 is 60 and Column T has 30 and 40 so 60/30 is 2 and 60/40 is 1.5 but it put 30 and 2 only and ignored 40 and 1.5. Maybe it just put the first values that met either condition.
 
Last edited:
Upvote 0
There is a problem with Row 3 as there are two values that meet your criteria... 60 divided by 30 equals 2 and also 60 divided by 40 equals 1.5. To get your stated results, I am assuming for such a situation that you want the result producing 2 and not the one producing 1.5 when both answers are present. With that assumption, try these two formulas...

Z1: =IF(ISNUMBER(FIND(N1/2,T1)),N1/2,IF(ISNUMBER(FIND(N1/1.5,T1)),N1/1.5,""))

AA1: =N1/Z1
 
Last edited:
Upvote 0
This is answer of why I happy find this site and Persons Like You & Peter_SSs.
Your answers always astonished me & I want to see your other answers to Challenged questions.
Wish You Best.
 
Upvote 0
There is a problem with Row 3 as there are two values that meet your criteria... 60 divided by 30 equals 2 and also 60 divided by 40 equals 1.5. To get your stated results, I am assuming for such a situation that you want the result producing 2 and not the one producing 1.5 when both answers are present. With that assumption, try these two formulas...

Z1: =IF(ISNUMBER(FIND(N1/2,T1)),N1/2,IF(ISNUMBER(FIND(N1/1.5,T1)),N1/1.5,""))

AA1: =N1/Z1
@Rick Rothstein

Wow, this is great!

In your formula, I think you meant to refer to row 2 in your cells. Also, I would actually like both results if one equals 1.5 and the other 2.
Is using an AND and CONCATENATE functions here worth it to get both results or is there something better?
 
Upvote 0
This is answer of why I happy find this site and Persons Like You & Peter_SSs.
Your answers always astonished me & I want to see your other answers to Challenged questions.
Wish You Best.
@maabadi

At least you had some type of response as I couldn't even figure out what to even try. You also used the "Find" function which Rick also used so you were on the right track!
 
Upvote 0
Try first row formula and drag it down.
Book1.xlsm
NSTYZAAABAC
1
25070, 25, 55252
36030, 35, 40302
4200150, 100, 1201002
5120100, 90, 80801.5
6
Sheet3
Cell Formulas
RangeFormula
Z2:Z5Z2=IF(ISNUMBER(FIND(N2/2,T2)),N2/2,IF(ISNUMBER(FIND(N2/1.5,T2)),N2/1.5,""))
AA2:AA5AA2=N2/Z2
 
Upvote 0
In your formula, I think you meant to refer to row 2 in your cells. Also, I would actually like both results if one equals 1.5 and the other 2.
Is using an AND and CONCATENATE functions here worth it to get both results or is there something better?
Give these formulas a try...

Z2: =SUBSTITUTE(TRIM(IF(ISNUMBER(FIND(N2/1.5,T2)),N2/1.5,"")&" "&IF(ISNUMBER(FIND(N2/2,T2)),N2/2,""))," ",", ")

AA2: =IFERROR(N1/Z1,"1.5, 2")
 
Upvote 0
Solution
Give these formulas a try...

Z2: =SUBSTITUTE(TRIM(IF(ISNUMBER(FIND(N2/1.5,T2)),N2/1.5,"")&" "&IF(ISNUMBER(FIND(N2/2,T2)),N2/2,""))," ",", ")

AA2: =IFERROR(N1/Z1,"1.5, 2")
@Rick Rothstein

Thanks Rick for all your help!! Your nested functions worked perfectly!

I marked your last post as my solution.
 
Upvote 0

Forum statistics

Threads
1,214,926
Messages
6,122,305
Members
449,079
Latest member
juggernaut24

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