Sumproduct to Table...

DonkeyOte

MrExcel MVP
Joined
Sep 6, 2002
Messages
9,124
Does anyone know of a utility / function or have themselves coded something that permits an end user to analyse a given Sumproduct formula in greater detail - ie returning the results of the generated array into tabular form ?

I've just sat down thinking this would be quite useful, ie I click on any sumproduct formula and run a routine to "Analyse" which in turn generates a new sheet with a matrix of the results...

However having just started coding this myself it is now dawning on me that this could prove very difficult (read beyond my abilities) ... breaking out the formula itself etc into component parts is pretty easy but actually evaluating each part is a little more difficult.

I suspect someone knows of an elegant way to do this and I'd love to see it... it may of course be that you can do this already but I don't know how...

Thanks,
Luke
 
Last edited:
FINE....

As for Step 3 in my "how to waste a day" routine... all it does it strip out the =SUMPRODUCT + ( + ) to leave the remainder... eg

=SUMPRODUCT(--(A1:A100=","),B1:B100)

becomes

--(A1:A100=","),B1:B100

Then iterates reworked string chr by chr and looks for the assigned delimiter
-- in code thus far hardwired to , but could be changed to * or ;

It then looks to split the string when it finds a delimiter but only if the count of parentheses is 0 at the time -- ie it is not between ( and ) ... if it is then in reality it's not going to be a valid delimiter as the , forms part of the component formula... eg the first , in the above string is part of the first component part... when it gets to the 2nd , the count of parentheses is 0 ... 1 open / 1 close .. so it then extracts that component and so on and so forth... there's probably a better way to do it using regular expressions or something but I'm not very clued up on that stuff... you could even jump through the string to each delimiter chr and count ( and count ) preceeding it - if count of ( less count of ) = 0 then it's a valid split... horses for courses...
 
Last edited:
Upvote 0

Excel Facts

Can Excel fill bagel flavors?
You can teach Excel a new custom list. Type the list in cells, File, Options, Advanced, Edit Custom Lists, Import, OK
Okay. Complicated, but less scary now. :biggrin: Nice logic!

Still can't work out the MATCH thing. Where are all the geniuses when you need them?!
 
Upvote 0
I dunno about the (other) geniuses, but I'm working on a formula parsing function...
 
Upvote 0
You can get Evaulate to evaluate the Match if you wrap it in an IF like so:

Code:
Evaluate("IF(ROW(" & rng.Address & "),ISNUMBER(MATCH(" & rng.Address & ",lookup_range,0)))")
 
Upvote 0
Richard - that's interesting. And quite annoying!

Small sidetrack:
ary = Evaluate("IF(row(B1),ISNUMBER(MATCH($B$1:$B$10,$B$1:$B$10,0)))") works for me but
ary = Evaluate("IF(1,ISNUMBER(MATCH($B$1:$B$10,$B$1:$B$10,0)))") doesn't. Any idea why?
 
Upvote 0
Welcome to the Geniuses ranks Mr Schollar... this approach works for things like:

N(OFFSET($C4,ROW($A$1:$A2)*-1,0))

also... so I guess the key now is to work out how to get this darn thing to determine if/when it requires row requirements... you could insert to default of rows.count and then remove errors but this seems a little resource-tastic... is there a clever way I wonder...

EDIT: scrap that... by jove I think you may have done it...
 
Upvote 0
Well that is interesting - I didn't know you didn't need to pass the range to the ROW function. So you can actually use ROW(). That is very interesting. Thanks Emma!
 
Upvote 0
Please test this... it works for me on everything I've tested thus far (using comma delimiter)

Code:
Sub Analyse_SumProduct_DONKEYOTE()
'-------------------------------------------------------------------------------------------------------------------------
'coded (poorly) by DonkeyOte Weds 22 Oct 2008
'hard bits coded by messrs. RoryA, Richard Schollar & Cornflake Girl
'abbreviations
'SP - SumProduct
'SPA - SumProduct Analysis
'-------------------------------------------------------------------------------------------------------------------------
'#DEFINE VARIABLES (Assign/Set where possible)
'-------------------------------------------------------------------------------------------------------------------------
Dim s_s1 As String: s_s1 = ActiveSheet.Name                 'to hold sheet name on which SP formula resides
Dim s_s2 As String                                          'to hold sheet name of SPA sheet (to be created)
Dim s_c1 As String: s_c1 = ActiveCell.Address(0, 0)         'to hold cell address in which SP formula resides
Dim s_c1_f As String: s_c1_f = ActiveCell.formula           'to hold SP formula being analysed
Dim s_c1_f_res As Long                                      'to hold result of SP formula being analysed
Dim i_c1_f_i As Long                                        'to hold mid char point when iterating formula string
Dim i_c1_p_cnt As Long                                      'to hold running total of parentheses
Dim i_c1_f_start As Long                                    'to hold start char pos of SP component
Dim s_c1_f_delim As String: s_c1_f_delim = ","              'to hold SP component delimiter (eg "," or "*") - change to InputBox later
Dim i_c1_f_c As Integer                                     'to hold count of "components" within SP formula
Dim l_c1_f_comp_i As Long                                   'incremental column flag of component parts
Dim s_c1_f_comp As String                                   'component part of formula as stored in row 5 on SPA sheet
Dim v_c1_f_output                                           'used to store result of component part
'-------------------------------------------------------------------------------------------------------------------------
'#SET APP SETTINGS
'-------------------------------------------------------------------------------------------------------------------------
With Application
    .ScreenUpdating = False
    .Calculation = xlCalculationManual
End With
'-------------------------------------------------------------------------------------------------------------------------
'#STEP 1: VALIDATE FORMULA BEING ANALYSED -- EXIT IF INAPPROPRIATE FOR THIS ROUTINE
'-------------------------------------------------------------------------------------------------------------------------
On Error Resume Next
s_c1_f_res = Evaluate(s_c1_f)
e = Err.Number
On Error GoTo 0
If InStr(UCase(s_c1_f), "=SUMPRODUCT") = 0 Then e = 1       'although formula is valid it's not a SUMPRODUCT formula!
If InStr(s_s1, "SPA") Then e = 1                            'firing code from previously created SPA sheet!
'exit routine if formula not valid for analysis
If e <> 0 Then
    MsgBox "Current Formula Not Valid for SUMPRODUCT Analysis"
    GoTo ExitHere:
End If
'-------------------------------------------------------------------------------------------------------------------------
'#STEP 2: INSERT A NEW SHEET ON WHICH THE SPA WILL BE HELD
'set name convention to utilise system time so as to remove possibility of duplication without need for ws testing / deletion
'-------------------------------------------------------------------------------------------------------------------------
Sheets.Add
ActiveSheet.Name = "SPA_" & Format(Now(), "DDMMYY_HHMMSS")
s_s2 = ActiveSheet.Name
Cells(1, 1) = "Formula Location:"
Cells(1, 2) = s_s1 & "!" & s_c1
Cells(2, 1) = "Formula: "
Cells(2, 2) = "'" & s_c1_f
Cells(3, 1) = "Result: "
Cells(3, 2) = s_c1_f_res
Cells(5, 1) = "Component Part(s):"
Cells(7, 1) = "Row/Column:"
Cells(7, 2) = "Result:"
'-------------------------------------------------------------------------------------------------------------------------
'#STEP 3: BEGINNING STRIPPING DOWN FORMULA INTO "COMPONENT" PARTS
'first remove =SUMPRODUCT() leaving just innards behind...
'loop the remaining string using predefined component "delimiter" (eg "," or "*") to break into parts (check parentheses)
'-------------------------------------------------------------------------------------------------------------------------
s_c1_f = Replace(s_c1_f, "=SUMPRODUCT(", "")
s_c1_f = Left(s_c1_f, Len(s_c1_f) - 1)
'default start pos of string to be 1
i_c1_f_start = 1
'iterate formula string
For i_c1_f_i = i_c1_f_start To Len(s_c1_f) Step 1
    'ascertain current character and act appropriately
    Select Case Mid(s_c1_f, i_c1_f_i, 1)
        Case "("
            'opening parentheses so add 1 to parentheses count
            i_c1_f_p_cnt = i_c1_f_p_cnt + 1
        Case ")"
            'closing parentheses so remove 1 from parentheses count
            i_c1_f_p_cnt = i_c1_f_p_cnt - 1
        Case s_c1_f_delim
            'current char appears to be delimiter however only valid end point IF count of parentheses is 0
            If i_c1_f_p_cnt = 0 Then
                'increment count of components
                i_c1_f_c = i_c1_f_c + 1
                'paste formula component as header in column B onwards (row 5)
                Cells(5, 1 + i_c1_f_c) = Chr(34) & Mid(s_c1_f, i_c1_f_start, i_c1_f_i - i_c1_f_start) & Chr(34)
                'reset start pos to be current string pos + 1
                i_c1_f_start = i_c1_f_i + 1
            End If
    End Select
Next i_c1_f_i
'insert final component
'increment count of components
i_c1_f_c = i_c1_f_c + 1
'paste formula component as header in column B onwards (row 5)
Cells(5, 1 + i_c1_f_c) = Chr(34) & Mid(s_c1_f, i_c1_f_start, i_c1_f_i - 1) & Chr(34)
'-------------------------------------------------------------------------------------------------------------------------
'#STEP 4: EVALUATE EACH COMPONENT PART & WRITE BACK RESULTS TO SPA SHEET (add total column)
'return to parent sheet such that correct relative range references are used prior to evaluation
'-------------------------------------------------------------------------------------------------------------------------
Sheets(s_s1).Select
For l_c1_f_comp_i = 2 To Sheets(s_s2).Cells(5, Columns.Count).End(xlToLeft).Column Step 1
    s_c1_f_comp = Sheets(s_s2).Cells(5, l_c1_f_comp_i)
    s_c1_f_comp = "IF(ROW(1:1)," & Mid(Left(s_c1_f_comp, Len(s_c1_f_comp) - 1), 2) & ")"
    v_c1_f_output = Application.Evaluate(s_c1_f_comp)
    Sheets(s_s2).Cells(8, l_c1_f_comp_i).Resize(UBound(v_c1_f_output)).Value = v_c1_f_output
Next l_c1_f_comp_i
Sheets(s_s2).Select
Cells(5, Columns.Count).End(xlToLeft).Offset(2, 1).Value = "Total(s)"
Cells(8, l_c1_f_comp_i).Resize(UBound(v_c1_f_output)).FormulaR1C1 = "=PRODUCT(RC2:RC[-1])"
Cells(8, l_c1_f_comp_i).Resize(UBound(v_c1_f_output)).formula = Cells(8, l_c1_f_comp_i).Resize(UBound(v_c1_f_output)).Value
Cells(8, l_c1_f_comp_i).Resize(UBound(v_c1_f_output)).Font.Bold = True
'-------------------------------------------------------------------------------------------------------------------------
'#STEP 5: FORMAT SPA SHEET
'-------------------------------------------------------------------------------------------------------------------------
Columns(1).AutoFit
Range(Cells(5, 2), Cells(5, 2).End(xlToRight)).Columns.AutoFit
'-------------------------------------------------------------------------------------------------------------------------
'#EXIT POINT
'-------------------------------------------------------------------------------------------------------------------------
ExitHere:
'-------------------------------------------------------------------------------------------------------------------------
'#RESET APP SETTINGS
'-------------------------------------------------------------------------------------------------------------------------
With Application
    .ScreenUpdating = True
    .Calculation = xlCalculationAutomatic
End With
'-------------------------------------------------------------------------------------------------------------------------
'#END
'-------------------------------------------------------------------------------------------------------------------------
End Sub
 
Last edited:
Upvote 0
You haven't dimmed e...

Or i_c1_f_p_cnt - I assume this is what i_c1_p_cnt should be?
 
Last edited:
Upvote 0
I missed another also... smartarse (note I can't say smarta$$ as that's censored!)

Code:
Option Explicit
Sub Analyse_SumProduct_DONKEYOTE()
'-------------------------------------------------------------------------------------------------------------------------
'coded (poorly) by DonkeyOte Weds 22 Oct 2008
'tough bits coded by messrs. rorya, RichardSchollar & CornflakeGirl (aka Rory, Richard & Emma)
'abbreviations
'SP - SumProduct
'SPA - SumProduct Analysis
'-------------------------------------------------------------------------------------------------------------------------
'#DEFINE VARIABLES (Assign/Set where possible)
'-------------------------------------------------------------------------------------------------------------------------
Dim s_s1 As String: s_s1 = ActiveSheet.Name                 'to hold sheet name on which SP formula resides
Dim s_s2 As String                                          'to hold sheet name of SPA sheet (to be created)
Dim s_c1 As String: s_c1 = ActiveCell.Address(0, 0)         'to hold cell address in which SP formula resides
Dim s_c1_f As String: s_c1_f = ActiveCell.formula           'to hold SP formula being analysed
Dim s_c1_f_res As Long                                      'to hold result of SP formula being analysed
Dim i_c1_f_i As Long                                        'to hold mid char point when iterating formula string
Dim i_c1_f_p_cnt As Long                                    'to hold running total of parentheses
Dim i_c1_f_start As Long                                    'to hold start char pos of SP component
Dim s_c1_f_delim As String: s_c1_f_delim = ","              'to hold SP component delimiter (eg "," or "*") - change to InputBox later
Dim i_c1_f_c As Integer                                     'to hold count of "components" within SP formula
Dim l_c1_f_comp_i As Long                                   'incremental column flag of component parts
Dim s_c1_f_comp As String                                   'component part of formula as stored in row 5 on SPA sheet
Dim v_c1_f_output                                           'used to store result of component part
Dim e As Long                                               'used to hold possible cause of error on initial evaulation
'-------------------------------------------------------------------------------------------------------------------------
'#SET APP SETTINGS
'-------------------------------------------------------------------------------------------------------------------------
With Application
    .ScreenUpdating = False
    .Calculation = xlCalculationManual
End With
'-------------------------------------------------------------------------------------------------------------------------
'#STEP 1: VALIDATE FORMULA BEING ANALYSED -- EXIT IF INAPPROPRIATE FOR THIS ROUTINE
'-------------------------------------------------------------------------------------------------------------------------
On Error Resume Next
s_c1_f_res = Evaluate(s_c1_f)
e = Err.Number
On Error GoTo 0
If InStr(UCase(s_c1_f), "=SUMPRODUCT") = 0 Then e = 1       'although formula is valid it's not a SUMPRODUCT formula!
If InStr(s_s1, "SPA") Then e = 1                            'firing code from previously created SPA sheet!
'exit routine if formula not valid for analysis
If e <> 0 Then
    MsgBox "Current Formula Not Valid for SUMPRODUCT Analysis"
    GoTo ExitHere:
End If
'-------------------------------------------------------------------------------------------------------------------------
'#STEP 2: INSERT A NEW SHEET ON WHICH THE SPA WILL BE HELD
'set name convention to utilise system time so as to remove possibility of duplication without need for ws testing / deletion
'set up headers
'-------------------------------------------------------------------------------------------------------------------------
Sheets.Add
ActiveSheet.Name = "SPA_" & Format(Now(), "DDMMYY_HHMMSS")
s_s2 = ActiveSheet.Name
Cells(1, 1) = "Formula Location:"
Cells(1, 2) = s_s1 & "!" & s_c1
Cells(2, 1) = "Formula: "
Cells(2, 2) = "'" & s_c1_f
Cells(3, 1) = "Result: "
Cells(3, 2) = s_c1_f_res
Cells(5, 1) = "Component Part(s):"
Cells(7, 1) = "Row/Column:"
Cells(7, 2) = "Result:"
'-------------------------------------------------------------------------------------------------------------------------
'#STEP 3: BEGINNING STRIPPING DOWN FORMULA INTO "COMPONENT" PARTS
'first remove =SUMPRODUCT() leaving just innards behind...
'loop the remaining string using predefined component "delimiter" (eg "," or "*") to break into parts (check parentheses)
'-------------------------------------------------------------------------------------------------------------------------
s_c1_f = Replace(s_c1_f, "=SUMPRODUCT(", "")
s_c1_f = Left(s_c1_f, Len(s_c1_f) - 1)
'default start pos of string to be 1
i_c1_f_start = 1
'iterate formula string
For i_c1_f_i = i_c1_f_start To Len(s_c1_f) Step 1
    'ascertain current character and act appropriately
    Select Case Mid(s_c1_f, i_c1_f_i, 1)
        Case "("
            'opening parentheses so add 1 to parentheses count
            i_c1_f_p_cnt = i_c1_f_p_cnt + 1
        Case ")"
            'closing parentheses so remove 1 from parentheses count
            i_c1_f_p_cnt = i_c1_f_p_cnt - 1
        Case s_c1_f_delim
            'current char appears to be delimiter however only valid end point IF count of parentheses is 0
            If i_c1_f_p_cnt = 0 Then
                'increment count of components
                i_c1_f_c = i_c1_f_c + 1
                'paste formula component as header in column B onwards (row 5)
                Cells(5, 1 + i_c1_f_c) = Chr(34) & Mid(s_c1_f, i_c1_f_start, i_c1_f_i - i_c1_f_start) & Chr(34)
                'reset start pos to be current string pos + 1
                i_c1_f_start = i_c1_f_i + 1
            End If
    End Select
Next i_c1_f_i
'insert final component
'increment count of components
i_c1_f_c = i_c1_f_c + 1
'paste formula component as header in column B onwards (row 5)
Cells(5, 1 + i_c1_f_c) = Chr(34) & Mid(s_c1_f, i_c1_f_start, i_c1_f_i - 1) & Chr(34)
'-------------------------------------------------------------------------------------------------------------------------
'#STEP 4: EVALUATE EACH COMPONENT PART & WRITE BACK RESULTS TO SPA SHEET (add total column)
'return to parent sheet such that correct relative range references are used prior to evaluation
'-------------------------------------------------------------------------------------------------------------------------
Sheets(s_s1).Select
For l_c1_f_comp_i = 2 To Sheets(s_s2).Cells(5, Columns.Count).End(xlToLeft).Column Step 1
    s_c1_f_comp = Sheets(s_s2).Cells(5, l_c1_f_comp_i)
    s_c1_f_comp = "IF(ROW(1:1)," & Mid(Left(s_c1_f_comp, Len(s_c1_f_comp) - 1), 2) & ")"
    v_c1_f_output = Application.Evaluate(s_c1_f_comp)
    Sheets(s_s2).Cells(8, l_c1_f_comp_i).Resize(UBound(v_c1_f_output)).Value = v_c1_f_output
Next l_c1_f_comp_i
Sheets(s_s2).Select
Cells(5, Columns.Count).End(xlToLeft).Offset(2, 1).Value = "Total(s)"
Cells(8, l_c1_f_comp_i).Resize(UBound(v_c1_f_output)).FormulaR1C1 = "=PRODUCT(RC2:RC[-1])"
Cells(8, l_c1_f_comp_i).Resize(UBound(v_c1_f_output)).formula = Cells(8, l_c1_f_comp_i).Resize(UBound(v_c1_f_output)).Value
Cells(8, l_c1_f_comp_i).Resize(UBound(v_c1_f_output)).Font.Bold = True
'-------------------------------------------------------------------------------------------------------------------------
'#STEP 5: FORMAT SPA SHEET
'-------------------------------------------------------------------------------------------------------------------------
Columns(1).AutoFit
Range(Cells(5, 2), Cells(5, 2).End(xlToRight)).Columns.AutoFit
'-------------------------------------------------------------------------------------------------------------------------
'#EXIT POINT
'-------------------------------------------------------------------------------------------------------------------------
ExitHere:
'-------------------------------------------------------------------------------------------------------------------------
'#RESET APP SETTINGS
'-------------------------------------------------------------------------------------------------------------------------
With Application
    .ScreenUpdating = True
    .Calculation = xlCalculationAutomatic
End With
'-------------------------------------------------------------------------------------------------------------------------
'#END
'-------------------------------------------------------------------------------------------------------------------------
End Sub

Next step to populate column A with relative info and try to capture both criteria and array values for ease of reference...

So big point -- this is only an initial test... if it works then we can streamline and make more useful (with more info) -- before Rory comes along with his and blows us all out of the water with his tea making, tap dancing solution...

(EDIT: variable names need a little work... ;-))
 
Last edited:
Upvote 0

Forum statistics

Threads
1,225,399
Messages
6,184,752
Members
453,254
Latest member
topeb

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