How to sum values from cells with varying strings and line breaks?

Adriante

New Member
Joined
Feb 4, 2025
Messages
3
Office Version
  1. 365
Platform
  1. Windows
Hi Excel community,
Trying to sum A, B, C values. If there is no number after a letter, then reference cell before (on the left).
If there is number after letter (or example A=10) then add to the sum "10".
Then get sums for each letter per specific period (month).

Columns E-G just to get an idea what I'd like formula to pull. Do not have Regex
1738660614619.png

1738660614619.png
 

Excel Facts

Copy a format multiple times
Select a formatted range. Double-click the Format Painter (left side of Home tab). You can paste formatting multiple times. Esc to stop
Try.
Date_Total_Data.xlsx
ABCDEFG
1DateTotalDataMonthItemSum
215-Jan20A=10JanuaryA129
320-Jan112A B=18B18
422-Jan7AC0
52-Feb2A BFebruaryA146
67-Feb144A C=100B122
718-Feb120B CC220
Sheet1
Cell Formulas
RangeFormula
G2:G4G2=LET(_Table, $A$2:$C$7, _Month, $E$2, _Item, F2, _Data, INDEX(_Table, 0, 3), _Data_N, ROWS(_Data), _Total, INDEX(_Table, 0, 2), _Date, INDEX(_Table, 0, 1), _Date_is_Month, TEXT(_Date, "mmmm") = _Month, _Array, SEQUENCE(_Data_N), _Sum, REDUCE(0, _Array, LAMBDA(acc,x, acc + IF(ISNUMBER(FIND(_Item & "=", INDEX(_Data, x))), INDEX(_Date_is_Month, x) * IFERROR(TEXTSPLIT(INDEX(TEXTSPLIT(INDEX(_Data, x), _Item & "="), , 2), CHAR(10)), 0), IF(ISNUMBER(FIND(_Item, INDEX(_Data, x))), INDEX(_Date_is_Month, x) * INDEX(_Total, x), 0)))), _Sum)
G5:G7G5=LET(_Table, $A$2:$C$7, _Month, $E$5, _Item, F5, _Data, INDEX(_Table, 0, 3), _Data_N, ROWS(_Data), _Total, INDEX(_Table, 0, 2), _Date, INDEX(_Table, 0, 1), _Date_is_Month, TEXT(_Date, "mmmm") = _Month, _Array, SEQUENCE(_Data_N), _Sum, REDUCE(0, _Array, LAMBDA(acc,x, acc + IF(ISNUMBER(FIND(_Item & "=", INDEX(_Data, x))), INDEX(_Date_is_Month, x) * IFERROR(TEXTSPLIT(INDEX(TEXTSPLIT(INDEX(_Data, x), _Item & "="), , 2), CHAR(10)), 0), IF(ISNUMBER(FIND(_Item, INDEX(_Data, x))), INDEX(_Date_is_Month, x) * INDEX(_Total, x), 0)))), _Sum)
 
Upvote 0
Solution
An array option. Note that the cells in E are end of months (i.e. 1/31/25, 2/28/25) and formatted as "mmmm" to simplify the formula.
Book1
ABCDEFG
1DateTotalDataMonthItemSum
21/15/2520A=10JanuaryA129
31/20/25112A B=18JanuaryB18
41/22/257AJanuaryC0
52/2/252A BFebruaryA146
62/7/25144A C=100FebruaryB122
72/18/25120B CFebruaryC220
Sheet6
Cell Formulas
RangeFormula
G2:G7G2=LET(a, +A2:A7,b, B2:B7,c,C2:C7, MAP(E2:E7, F2:F7, LAMBDA(e,f, LET( g, EOMONTH(a,0) = e, x, IF(ISNUMBER(SEARCH(f & CHAR(10), c & CHAR(10)))*g,b,0), y, --TEXTAFTER(c, f & "=",,,,0)*g, SUM(x, y)))) )
Dynamic array formulas.
 
Last edited:
Upvote 0
This works perfectly! Thank you! Must admit - would not have been able to figure this out by myself and ..... I need a Tutor. Speaking of - does anyone know a good tutor ?
 
Upvote 0
Would like to mark this as a solution, too. EOM data needs to be added, however the benefit we get in turn is shorter formula.
 
Upvote 0
This works perfectly! Thank you! Must admit - would not have been able to figure this out by myself and ..... I need a Tutor. Speaking of - does anyone know a good tutor ?
You'r welcome.
I am glad it works.
 
Upvote 0
Here is a more compact option that doesn't require different formulas or different structure.
It does assume (as I believe the earlier suggestions do too) that the text values in column C would always be single letters. That is, you would never have in a cell something like "XA=10"

25 02 05.xlsm
ABCDEFG
1DateTotalDataMonthItemSum
215-Jan20A=10JanuaryA129
320-Jan112A B=18B18
422-Jan7AC0
52-Feb2A BFebruaryA146
67-Feb144A C=100B122
718-Feb120B CC220
Adriante
Cell Formulas
RangeFormula
G2:G7G2=LET(c,C$2:C$7,SUM((TEXT(A$2:A$7,"mmmm")=LOOKUP("z",E$2:E2))*IF(ISNUMBER(FIND(F2&"=",c)), --TEXTBEFORE(TEXTAFTER(c,F2&"="),CHAR(10),,,1),IF(ISNUMBER(FIND(F2,c)),B$2:B$7,0))))
 
Upvote 0

Forum statistics

Threads
1,226,266
Messages
6,189,936
Members
453,583
Latest member
Ok_category1816

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