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:
Luke - how hard would it be to have both , and * as delimiters? Just been doing a quick search of the board and there are quite a lot of examples of people using both.

Hmm... should be possible... but first let me take out the rubbish and make a cup of tea...
it's so rock'n'roll out here in rural Suffolk!
 
Upvote 0

Excel Facts

Square and cube roots
The =SQRT(25) is a square root. For a cube root, use =125^(1/3). For a fourth root, use =625^(1/4).
From the help file on PRODUCT:
Arguments that are numbers, logical values, or text representations of numbers are counted; arguments that are error values or text that cannot be translated into numbers cause errors.
If an argument is an array or reference, only numbers in the array or reference are counted. Empty cells, logical values, text, or error values in the array or reference are ignored.

I tested it: =PRODUCT(FALSE,4) = 0. But =PRODUCT(A1,4) where A1 contains FALSE = 4. Still odd!
 
Upvote 0
Wouldn't an error handler be better than On Error Goto 0?
 
Upvote 0
Wouldn't an error handler be better than On Error Goto 0?

Yes finished product and all that jazz...
Would probably have multiple handlers to account for different stages throughout code but at present just one handler setup (for evaluation) and then a reset post evaluation whilst testing...

The more people that test the better -- with the fix to the total column for boolean returns it's working for me as I say on pretty much anything I try... the notion of multiple delimiters is an interesting one... we/I must be missing a simple basic (and thus elegant) piece of logic ...
 
Upvote 0
Luke - I just broke it :(

This is my sumproduct
Excel Workbook
BCDEF
152019181716
16678910
17
18120254401560730
Sheet1


and this is what your code gave me

Excel Workbook
ABCD
1Formula Location:Sheet1!F20
2Formula:=SUMPRODUCT($B15:F$15,N(OFFSET($B$16,0,COLUMN($B$16)+COUNT($B16:F$16)-COLUMN($B16:F$16)-1,1)))
3Result:730
4
5Component Part(s):"$B15:F$15""N(OFFSET($B$16,0,COLUMN($B$16)+COUNT($B16:F$16)-COLUMN($B16:F$16)-1,1))"
6
7Row/Column:Result:Total(s)
82010200
92010200
102010200
112010200
122010200
SPA_231008_094945
 
Upvote 0
issue of transposing array do you think ?

EDIT: so when I said "it works on everything" this has obviously exposed one major flaw in my testing procedure... (or lack thereof)
 
Last edited:
Upvote 0
Hehe - to be fair, I wouldn't be too worried if it couldn't handle the second argument - can't see that coming up too often! Not handling a horizontal range more of a thing.

EDIT: just in case anyone is paying more attention than me - the reason it says it's evaluating F20 is because I deleted two rows after running Luke's code. Always helpful! It's really working on the sumproduct in F18.
 
Last edited:
Upvote 0
Only needs a small tweak to do horizontal arrays I think - something like:
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 r_c1 As Range: Set r_c1 = ActiveCell
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                                  'to hold SP component delimiter (eg "," or "*") set via InputBox
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
Dim lngColCount As Long
'-------------------------------------------------------------------------------------------------------------------------
'#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)
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 1a: DETERMINE DELIMITER (let user decide...)
'-------------------------------------------------------------------------------------------------------------------------
s_c1_f_delim = Application.InputBox("Enter Delimiter" & vbCrLf & "Note: Normally one of , * ;", "Delimiter", ",", Type:=2)
Select Case s_c1_f_delim
    Case ",", "*", ";"
    Case Else
        MsgBox s_c1_f_delim & "Not Valid for SUMPRODUCT Analysis"
        GoTo ExitHere:
End Select
'-------------------------------------------------------------------------------------------------------------------------
'#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)
'-------------------------------------------------------------------------------------------------------------------------
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 = r_c1.Parent.Evaluate(s_c1_f_comp)
    On Error Resume Next
    lngColCount = UBound(v_c1_f_output, 2)
    On Error GoTo Fatality:
    If lngColCount = 0 Then
      Sheets(s_s2).Cells(8, l_c1_f_comp_i).Resize(UBound(v_c1_f_output)).Value = Application.Transpose(v_c1_f_output)
   Else
      Sheets(s_s2).Cells(8, l_c1_f_comp_i).Resize(UBound(v_c1_f_output)).Value = v_c1_f_output
   End If
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 = "=IF(OR(SUMPRODUCT(--(ISNUMBER(--(RC2:RC[-1]))=FALSE)),COUNTIF(RC2:RC[-1],FALSE)),0,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
'-------------------------------------------------------------------------------------------------------------------------
Exit Sub
Fatality:
MsgBox "Fatal Error Occurred Processing Component Part", vbCritical, "Fatal Error"
Resume ExitHere
End Sub
 
Upvote 0
The 2nd argument shouldn't be an issue -- I've tested on something similar (vertically!) and it worked fine... the issue is definitely related to the fact that it needs to transpose the array... interestingly when you evaluate against a vertical range it produces an array with both vertical & horizontal dimensions but with a purely horizontal array it does not return a value for the vertical dimension... does that make sense ?

if you evaluate say

--(ISNUMBER(MATCH($A$2:$A$10,$E$2:$E$4,0)))

You can see the output is defined as Variant(1 to 9)/Variant(1 to 1)

so

UBound(output,1) = 9
UBound(output,2) = 1


however, if you evaluate:

--(A1:D1=A6)

You can see the output is defined as Variant/Variant(1 to 4)

So the latter does not generate a 1 to 1 for the vertical... it only sees the array as having a horizontal value... which means

UBound(output,1) = 4
UBound(output,2) = error

does that make sense ?

If it always generated both dimensions I could transpose the data quite easily... I guess I can assume (?) that if UBound(ouput,2) is error then must be horizontal argument and thus requires transposing...
 
Upvote 0

Forum statistics

Threads
1,225,400
Messages
6,184,762
Members
453,255
Latest member
excelbit

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