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:
I've got the T-shirt to prove it. :)
 
Upvote 0

Excel Facts

Add Bullets to Range
Select range. Press Ctrl+1. On Number tab, choose Custom. Type Alt+7 then space then @ sign (using 7 on numeric keypad)
"You have a big brain, a good heart, and an ego the size of Montana."

It is a thing of beauty.

(The sub. Not your ego.)
 
Upvote 0
Ah, back to the West Wing! :)
(it's more like Texas, though)
 
Upvote 0
I'm not far off getting this to work for different permutations of syntax !!

You have no frigging idea as to how cool I think this is... we (read Rory) shall revolutionise how we illustrate the mechanics of SUMPRODUCT on this board !!

Rory, if I ever meet you I will buy you a beer (or ****tail ... I don't know what you high rollers drink thesedays!)
 
Upvote 0
Don't whatever you do make any open ended pledges like "I'll buy you drinks for the evening". You'll be bankrupt 90 minutes into the night...
 
Upvote 0
To quote Garth:
"So bring me two pina coladas
One for each hand"
 
Upvote 0
Guinness is preferable (which is why, in London, you'll end up bankrupt!)
 
Upvote 0
Hello everyone,

First I'd like to thank DonkeyOte for posting a request that I absolutely need in a way that was much clearer than the way I ever could of. Also, thank you rorya for posting the code.

I was hoping someone could help me tweak it a bit. What I'm hoping for is if the values of the Sumproduct all return a 1, to list the value in Rows C and D of the sheet that is evaluated.

I can do it with a loop like:
Code:
For i = 1 To 489
If Sheet11.Range("A" & i).Value And Sheet11.Range("B" & i).Value And Sheet11.Range("C" & i).Value Then
    Sheet11.Range("E" & i).Value = Sheet2.Range("C" & i + 9).Value
End If
Next i

which works on a formula like:
=SUMPRODUCT(--('Test'!$G$10:$G$498>1/1/2000),--('Test'!$B$10:$B$498=$C$26))

but wouldn't work on a formula like:
=SUMPRODUCT(--('Test'!$T$10:$T$498<>""),--('Test'!$Y$10:$Y$498<>""),--('Test'!$B$10:$B$498=$C$26))

without going in and modifying my loop to check for another 1 in column D. Surely there has to be an easier and more dynamic way of doing it.

If someone could help me tweak the code a bit, I'd be more than happy to send you all the virtual beer you can drink... :beerchug:
 
Upvote 0
sous2817, will come back to yours sorry... having an issue I need Rory to have a look at for me...

Rory, given the below scenario

Excel Workbook
ABCDE
1IDDateAmountID
2A01/10/200820A
3B01/08/200830E
4A01/10/200810S
5D01/04/2008100
6A01/10/200720
7E01/03/200830
8S23/01/2008450
9S01/07/200845
10X30/10/200830
11
1201/10/2008
1330
1460
Sheet7


Running the below code against A13 fails whereas against A14 it works... any ideas ? It's to do with the output and I can't determine the cause... I am trying against a variety of different sumproduct formulae and most work ok but figured I'd put up an example... probably something obvious...

Apologies in advance for my butchering of your elegant code...

Code:
Sub Analyse_SumProduct_DONKEYOTE()
'-------------------------------------------------------------------------------------------------------------------------
'coded (poorly) by DonkeyOte Weds 22 Oct 2008
'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
'set up headers and format column A width
'-------------------------------------------------------------------------------------------------------------------------
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) = Mid(s_c1_f, i_c1_f_start, i_c1_f_i - i_c1_f_start)
                '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) = Mid(s_c1_f, i_c1_f_start, i_c1_f_i - 1)
'-------------------------------------------------------------------------------------------------------------------------
'#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)
    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
 
Upvote 0

Forum statistics

Threads
1,225,399
Messages
6,184,747
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