Calculation with comma separated values in a cell

lind33

New Member
Joined
Jun 25, 2019
Messages
14
Office Version
  1. 2016
Platform
  1. Windows
I have an example ordered comma separated list in a cell. Values are comma separated. they can be 1 digit or 2 digits.

Book2.xlsx

I'm trying to get the difference between the first value and the last value, and add 1 to the result. This is what I tried to do:

B2: = (RIGHT(A2,1)-LEFT(A2,1))+1

This works fine if all the values are single digit, but if the last value is two digits, then it doesn't give the correct result.

Is there a better way of writing this formula which works fine both for single and double digits? please. thanks

On the link to excel file above, there are some data and expected results, and how the expected results obtained.
 

Some videos you may like

Excel Facts

What is the last column in Excel?
Excel columns run from A to Z, AA to AZ, AAA to XFD. The last column is XFD.

mohadin

Well-known Member
Joined
Mar 22, 2015
Messages
1,091
Office Version
  1. 2013
Platform
  1. Windows
Hi
Try
Excel Formula:
B2==(MID(A2,FIND(",",A2)+1,255)-LEFT(A2,FIND(",",A2)-1))+1
 

lind33

New Member
Joined
Jun 25, 2019
Messages
14
Office Version
  1. 2016
Platform
  1. Windows
I tried it but I'm getting #VALUE! error.

1605956564292.png
 

mohadin

Well-known Member
Joined
Mar 22, 2015
Messages
1,091
Office Version
  1. 2013
Platform
  1. Windows
All right
I see
Use this UDF
Rich (BB code):
Function calc(targetcell As Variant)
If targetcell <> "" Then
    x = Split(targetcell, ",")
     calc = (x(UBound(x)) - x(0)) + 1
    Else: calc = 0: End If
End Function

C1=calc(a1)
 
Solution

lind33

New Member
Joined
Jun 25, 2019
Messages
14
Office Version
  1. 2016
Platform
  1. Windows

ADVERTISEMENT

Thanks, Mohadin. the UDF works for all cells.
 

fadee2

Active Member
Joined
Nov 7, 2020
Messages
335
Office Version
  1. 2019
Platform
  1. Windows
another option

Excel Formula:
=(IF(LEFT(RIGHT(A2,SEARCH(",",A2)),1)=",",RIGHT(A2,SEARCH(",",A2)-1),RIGHT(A2,SEARCH(",",A2)))-LEFT(A2,SEARCH(",",A2)-1))+1
 

mohadin

Well-known Member
Joined
Mar 22, 2015
Messages
1,091
Office Version
  1. 2013
Platform
  1. Windows

ADVERTISEMENT

You are very welcome
And thank you for the feedback
Be happy
 

lind33

New Member
Joined
Jun 25, 2019
Messages
14
Office Version
  1. 2016
Platform
  1. Windows
another option

Excel Formula:
=(IF(LEFT(RIGHT(A2,SEARCH(",",A2)),1)=",",RIGHT(A2,SEARCH(",",A2)-1),RIGHT(A2,SEARCH(",",A2)))-LEFT(A2,SEARCH(",",A2)-1))+1
Thanks, Fadee2. yes this formula works too.
 

fadee2

Active Member
Joined
Nov 7, 2020
Messages
335
Office Version
  1. 2019
Platform
  1. Windows
Your welcome and thanks for the followup.
 

mohadin

Well-known Member
Joined
Mar 22, 2015
Messages
1,091
Office Version
  1. 2013
Platform
  1. Windows
@lind33
Mind you The other formula should be some thing like
Excel Formula:
=IFERROR((IF(LEFT(RIGHT(A1,SEARCH(",",A1)),1)=",",RIGHT(A1,SEARCH(",",A1)-1),RIGHT(A1,SEARCH(",",A1)))-LEFT(A1,SEARCH(",",A1)-1))+1,0)
 

Watch MrExcel Video

Forum statistics

Threads
1,127,120
Messages
5,622,851
Members
415,934
Latest member
adstocking

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
Top