Formula does not work

Help_Me_Excel

New Member
Joined
Jun 13, 2011
Messages
14
Sum Cells with multiple Numbers and multiple Text, within a cell

Data
Cell C
Row 17 30K 12.5% 25K 13.0%


Row 18 50K 14.0%

Row 19 5K 13.0% 105K 13.5%

Row 20
=SUM((0&TRIM(MID(TRANSPOSE(SUBSTITUTE(C17:C20," "," ")),FIND("^^",SUBSTITUTE(TRANSPOSE(SUBSTITUTE(C17:C20," "," ")),"K","^^",ROW(INDIRECT("1:"&MAX(LEN(C17:C20)-LEN(SUBSTITUTE(C17:C20,"K",""))))))&REPT("000^^",MAX(LEN(C17:C20)-LEN(SUBSTITUTE(C17:C20,"K","")))))-3,3)))+0)


should total 215
<HR style="COLOR: #ffffff; BACKGROUND-COLOR: #ffffff" SIZE=1>
<!-- / icon and title --><!-- message -->any idea why I am getting a #value error, when I use this array




=SUM((0&TRIM(MID(TRANSPOSE(SUBSTITUTE(C17:C20," "," ")),FIND("^^",SUBSTITUTE(TRANSPOSE(SUBSTITUTE(C17:C20," "," ")),"K","^^",ROW(INDIRECT("1:"&MAX(LEN(C17:C20)-LEN(SUBSTITUTE(C17:C20,"K",""))))))&REPT("000^^",MAX(LEN(C17:C20)-LEN(SUBSTITUTE(C17:C20,"K","")))))-3,3)))+0)

I used CTRL + SHIFT + ENTER
<!-- / message -->
 

Excel Facts

What do {} around a formula in the formula bar mean?
{Formula} means the formula was entered using Ctrl+Shift+Enter signifying an old-style array formula.
If it is not working as an array, it probably means that the formulas only use a reference, not a range.
 
Upvote 0
That's a lot of formula for a little task.

Bad logic is returning an array of zero and negative values to the start position of the MID function.

Try (array formula)

=SUM(IF(RIGHT(C17:F20)="K",--SUBSTITUTE(C17:F20,"K","")))
 
Upvote 0
I tried SUM(IF(RIGHT(C17:F20)="K",--SUBSTITUTE(C17:F20,"K",""))) this array and it does not work, in one cell I have multiple K's and % signs.

example cell C 17 would include 30K 12.5 100K 13.0% 5K 13.5%
cell c 18 would include 10K 13.5%

and I would like to just add up all the K values

any help is greatly appreciated
 
Upvote 0
Sum Cells with multiple Numbers and multiple Text, within a cell

Data
Cell C
Row 17 30K 12.5% 25K 13.0%


Row 18 50K 14.0%

Row 19 5K 13.0% 105K 13.5%

Row 20
=SUM((0&TRIM(MID(TRANSPOSE(SUBSTITUTE(C17:C20," "," ")),FIND("^^",SUBSTITUTE(TRANSPOSE(SUBSTITUTE(C17:C20," "," ")),"K","^^",ROW(INDIRECT("1:"&MAX(LEN(C17:C20)-LEN(SUBSTITUTE(C17:C20,"K",""))))))&REPT("000^^",MAX(LEN(C17:C20)-LEN(SUBSTITUTE(C17:C20,"K","")))))-3,3)))+0)


should total 215

<HR style="COLOR: #ffffff; BACKGROUND-COLOR: #ffffff" SIZE=1>
<!-- / icon and title --><!-- message -->any idea why I am getting a #value error, when I use this array




=SUM((0&TRIM(MID(TRANSPOSE(SUBSTITUTE(C17:C20," "," ")),FIND("^^",SUBSTITUTE(TRANSPOSE(SUBSTITUTE(C17:C20," "," ")),"K","^^",ROW(INDIRECT("1:"&MAX(LEN(C17:C20)-LEN(SUBSTITUTE(C17:C20,"K",""))))))&REPT("000^^",MAX(LEN(C17:C20)-LEN(SUBSTITUTE(C17:C20,"K","")))))-3,3)))+0)

I used CTRL + SHIFT + ENTER
<!-- / message -->
If you can put the data in individual cells then it would be a whole lot easier!

Book1
CDEF
1730K12.50%25K13.00%
1850K14.00%__
195K13.00%105K13.50%
20____
21215___
Sheet1

Array formula** entered in C21:

=SUM(IF(ISNUMBER(FIND("K",C17:F19)),--LEFT(C17:F19,LEN(C17:F19)-1)))

** array formulas need to be entered using the key
combination of CTRL,SHIFT,ENTER (not just ENTER).
Hold down both the CTRL key and the SHIFT key
then hit ENTER.

You can even use Text to Columns to parse it!
 
Upvote 0
If you want to keep it in one cell then you need to ensure that all K values are 3 digits, the easiest way to do this is to fire 2 leading zeros to each of the numeric values in the string, i.e.

=SUM((0&TRIM(MID(TRANSPOSE("00"&SUBSTITUTE(C17:C20," "," 00")),FIND("^^",SUBSTITUTE(TRANSPOSE("00"&SUBSTITUTE(C17:C20," "," 00")),"K","^^",ROW(INDIRECT("1:"&MAX(LEN(C17:C20)-LEN(SUBSTITUTE(C17:C20,"K",""))))))&REPT("000^^",MAX(LEN(C17:C20)-LEN(SUBSTITUTE(C17:C20,"K","")))))-3,3)))+0)

As Biff said, it would be a lot easier if you parse the values to individual cells, I misread your original post and my previous suggestion was also based on that fact.
 
Upvote 0

Forum statistics

Threads
1,224,588
Messages
6,179,743
Members
452,940
Latest member
rootytrip

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