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:
Yes reset is used to restart the process if mid way through processing a formula based on input delimiter etc it can be determined that the dimensions of the arrays generated by each component are not common -- the classic example of this was the:

=SUMPRODUCT(A1:A5*B1:F1)

If you put * as delimiter you will get an incorrect result obviously... if you put , as delimiter you will get a correct result... in the above instance the * is not a delimiter per se... the formula must be evaulated as one component.

Assuming user put * as delimiter the code would first split the formula down into parts, namely:

A1:A5 and B1:F1

It would evaluate and thus return A1:A5 prior to evaluating B1:F1... on evaluation of B1:F1 it would determine that the UBound value of the 2nd dimension would be 0 (1 to 5, nothing) whereas for the first component it was 1 (1 to 5, 1 to 1) ... thus in this case the formula can not be assessed in 2 parts as they are not of common "dimensions" and thus the formula must be reassessed in full delimiter-free -- ie evaluate A1:A5*B1:F1 as one calculation.

The "reset" is essentially invoked when the above occurs (ie the UBound value of 2nd dimension on any given array <> that of the very first component processed). When invoked the initial SPA sheet created is deleted and the formula is reprocessed in full delimiter-free so as to return correct result.

Does that clear things up at all ?
 
Upvote 0

Excel Facts

Shade all formula cells
To shade all formula cells: Home, Find & Select, Formulas to select all formulas. Then apply a light fill color.
That's true if you don't array enter it. Using a simple:
=SUMPRODUCT((A1:A10=5)*C1:C10)
in B1, I get 2 areas and 20 cells as precedents. Haven't done any real stress testing though.
 
Upvote 0
Not trying to be awkward but regards precedents etc -- perhaps a new thread ? It would be useful out of SUMPRODUCT context also... and could refer to this thread... (and v-v) -- for now I want to try and finish off the actual results matrix... reiterate... not trying to be awkward... but this is already 125 posts or something nuts and I suspect the topic of returning underlying values could be equally lengthy and of more interest to more people than this topic is... (I suspect a lot of people don't even look here now for good reason... ;-))
 
Upvote 0
Re: mixed delimiters... having just posted reply to xld regards reset I think I'm actually making this more complex than need be... I think you can assume any/all of: , * ; to be delimiters where count of parentheses is 0... if * is not a true delimiter the "reset" will handle that anyway.

Please find reworked code below, xld I hope this resolves your issue ?

Notes:
I've left in the variable to hold the default delimiter purely for reset reasons.
The below now removes requirement for Application.InputBox to capture delimiter from user (a good thing IMO)

Code:
Option Explicit
Sub Analyse_SumProduct_DONKEYOTE()
'-------------------------------------------------------------------------------------------------------------------------
'coded (poorly) by DonkeyOte Weds 22 to Fri 24 Oct 2008
'with not inconsiderable help from messrs. rorya, RichardSchollar & CornflakeGirl (muliebrity notwithstanding) - a.k.a. Rory, Richard & Emma.
'-------------------------------------------------------------------------------------------------------------------------
'abbreviations
'SP - SumProduct
'SPA - SumProduct Analysis
'-------------------------------------------------------------------------------------------------------------------------
'#DEFINE VARIABLES (Assign/Set where possible)
'-------------------------------------------------------------------------------------------------------------------------
'Range Type Variable(s)
'-------------------------------------------------------------------------------------------------------------------------
Dim r_c1 As Range: Set r_c1 = ActiveCell                    'to hold active cell as range
'-------------------------------------------------------------------------------------------------------------------------
'String Type Variable(s)
'-------------------------------------------------------------------------------------------------------------------------
Dim s_c1_f As String: s_c1_f = ActiveCell.Formula           'to hold SP formula being analysed
Dim s_c1_f_res As Double                                    'to hold result of SP formula being analysed
Dim s_c1_f_delim As String                                  'to hold SP component delimiter (eg "," or "*") set via InputBox
Dim s_c1_f_comp As String                                   'component part of formula as stored in row 5 on SPA sheet
Dim s_e_msgbox_str As String                                'used to hold error message displayed to end user on fatal error
Dim s_SPA_res_f As String                                   'used to hold formula written dynamically for 1+ column returns
'-------------------------------------------------------------------------------------------------------------------------
'Integer Type Variable(s)
'-------------------------------------------------------------------------------------------------------------------------
Dim i_c1_f_i As Integer                                     'to hold mid char point when iterating formula string
Dim i_c1_f_p_cnt As Integer                                 'to hold running total of parentheses
Dim i_c1_f_start As Integer                                 'to hold start char pos of SP component
Dim i_c1_f_c As Integer                                     'to hold count of "components" within SP formula
Dim i_insert_col_i As Integer                               'used for resizing SPA where 1+ rows / 1 + columns (1+ component)
Dim i_reset As Integer                                      'reset flag
Dim i_SPA_res_i As Integer                                  'counter used in conjunction with s_SPA_res_f
Dim i_SPA_res_cnt As Integer                                'counter used in conjunction with s_SPA_res_f
'-------------------------------------------------------------------------------------------------------------------------
'Long Type Variable(s)
'-------------------------------------------------------------------------------------------------------------------------
Dim l_calc As Long                                          'to hold calcuation settings
Dim l_e As Long                                             'used to hold possible cause of error on initial evaulation
Dim l_c1_f_comp_i As Long                                   'incremental column flag of component parts
Dim l_v_output_a_lbound As Long
Dim l_v_output_a_ubound As Long
Dim l_v_output_b_lbound As Long
Dim l_v_output_b_ubound As Long
Dim l_max_v_output_b_ubound As Long                         'used for error handling in dealing with arrays
Dim l_v_output_item_i As Long                                'used to populate col A on SPA
'-------------------------------------------------------------------------------------------------------------------------
'Variant / Undefined Type Variable(s)
'-------------------------------------------------------------------------------------------------------------------------
Dim v_c1_f_output                                           'used to store output array of component part
'-------------------------------------------------------------------------------------------------------------------------
'#END VARIABLES
'-------------------------------------------------------------------------------------------------------------------------
'-------------------------------------------------------------------------------------------------------------------------
'#SET APP SETTINGS (store current)
'-------------------------------------------------------------------------------------------------------------------------
l_calc = Application.Calculation
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 l_e = 0 And InStr(UCase(s_c1_f), "SUMPRODUCT") = 0 Then l_e = 1                      'not a SUMPRODUCT formula
If l_e = 0 And Left(UCase(s_c1_f), 11) <> "=SUMPRODUCT" Then l_e = 2                    'not self contained SUMPRODUCT (eg =IF(x=y,1,SUMPRODUCT())
If l_e = 0 And Len(s_c1_f) - Len(Replace(s_c1_f, "SUMPRODUCT", "")) > 10 Then l_e = 3   'embedded SUMPRODUCTS (too complex)
If l_e = 0 And InStr(r_c1.Parent.Name, "SPA") Then l_e = 4                              'firing code from previously created SPA sheet!
'exit routine if formula not valid for analysis
If l_e <> 0 Then
    Select Case l_e
        Case 1
            s_e_msgbox_str = "Formula is not a SUMPRODUCT Formula"
        Case 2
            s_e_msgbox_str = "Formula is not a self contained SUMPRODUCT Formula" & vbCrLf & vbCrLf & _
                                "If appropriate split the SUMPRODUCT(S) and evaluate each separately."
        Case 3
            s_e_msgbox_str = "Formula contains embedded SUMPRODUCTS and is thus deemed too complex." & vbCrLf & vbCrLf & _
                                "If appropriate split the SUMPRODUCT(S) and evaluate each separately."
        Case 4
            s_e_msgbox_str = "This Formula does not reside on a valid Sheet"
    End Select
    MsgBox s_e_msgbox_str, vbCritical, "Analysis Not Possible"
    GoTo ExitHere
End If
'-------------------------------------------------------------------------------------------------------------------------
'#STEP 1a: DETERMINE DELIMITER (default to comma)
'-------------------------------------------------------------------------------------------------------------------------
s_c1_f_delim = ","
'-------------------------------------------------------------------------------------------------------------------------
'#STEP 1b: RESET POINT -- used only where original routine has reset
'(due to computational issues based on original delimiter and array dimensions)
'set delimiter to blank (handled in split)
'-------------------------------------------------------------------------------------------------------------------------
Reset:
If i_reset = 1 Then
    s_c1_f_delim = ""               'reset delimimter
    i_reset = 0                     'reset the reset (!)
    i_c1_f_c = 0                    'reset count of components
    s_c1_f = ActiveCell.Formula     'reset formula being analysed
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")
Cells(1, 1) = "Formula Location:"
ActiveSheet.Hyperlinks.Add Anchor:=Cells(1, 2), Address:="", SubAddress:="'" & r_c1.Parent.Name & "'!" & r_c1.Address(0, 0), TextToDisplay:="'" & r_c1.Parent.Name & "'!" & r_c1.Address
Cells(2, 1) = "Formula: "
Cells(2, 2) = "'" & s_c1_f
Cells(3, 1) = "Result: "
Cells(3, 2) = s_c1_f_res
Cells(4, 1) = "Delimiter:"
Cells(4, 2) = IIf(s_c1_f_delim = "", "NA", s_c1_f_delim)
Cells(5, 1) = "Component Part(s):"
Cells(6, 1) = "Array Row(s):"
Cells(7, 1) = "Array Column(s):"
Cells(9, 1) = "Record:"
'-------------------------------------------------------------------------------------------------------------------------
'#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
'default running count of parentheses to be 0
i_c1_f_p_cnt = 0
'if delimiter is blank this is because of a reset which means the entire formula must be computed without components
If s_c1_f_delim <> "" Then
    '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 ",", "*", ";"
                'current char appears to be delimiter however only valid end point IF count of parentheses is 0
                'if comma and count of parentheses is 0 then must be delimiter whether defined or not...
                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
End If
'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)
'-------------------------------------------------------------------------------------------------------------------------
'default starting position to B (first column containing a component)
l_c1_f_comp_i = 2
'iterate components (use Do Until as opposed to For Next given requisite column insertions below for multi column output)
Do Until Cells(5, l_c1_f_comp_i) = ""
    'set result header
    Cells(9, l_c1_f_comp_i) = "Result(s)"
    s_c1_f_comp = 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)
    'set array boundaries
    '1+ row / 1 column will generate (1 to x (rows), 1 to 1 (columns))
    '1 row / 1 + column will generate (1 to x (columns), Nothing)
    '1+ row / 1 + column will generate (1 to x (rows), 1 to y (columns))
    On Error Resume Next
    l_v_output_a_lbound = LBound(v_c1_f_output, 1)
    l_v_output_a_ubound = UBound(v_c1_f_output, 1)
    l_v_output_b_lbound = LBound(v_c1_f_output, 2)
    l_v_output_b_ubound = UBound(v_c1_f_output, 2)
    'handling first component part ?
    If l_c1_f_comp_i = 2 Then
        'default max l_v_output_b_ubound to be first b_ubound value (set on first component)
        'used to establish later as to whether or not component parts of differing dimensions (requiring reset of calculation)
        l_max_v_output_b_ubound = l_v_output_b_ubound
        'populate SPA Col A with range details ?
        For l_v_output_item_i = 1 To Application.WorksheetFunction.Max(l_v_output_a_ubound, l_v_output_b_ubound) Step 1
            Cells(l_v_output_item_i + 9, 1) = l_v_output_item_i
        Next l_v_output_item_i
    End If
    'list array dimensions in SPA sheet -- if b array is nothing then purely column based SUMPRODUCT so rows = 0
    Select Case l_v_output_b_ubound
        Case 0
            'just columns
            Cells(6, l_c1_f_comp_i) = 1
            Cells(7, l_c1_f_comp_i) = l_v_output_a_ubound
        Case Else
            'both rows and columns
            Cells(6, l_c1_f_comp_i) = l_v_output_a_ubound
            Cells(7, l_c1_f_comp_i) = l_v_output_b_ubound
    End Select
    'before doing anything check current l_v_output_b_ubound to max thus far
    'point being if latest ubound value > prior max then need to do a singular return for this entire formula (no delimiter)
    If l_v_output_b_ubound <> l_max_v_output_b_ubound Then
        'reset
        Application.DisplayAlerts = False
        ActiveSheet.Delete
        Application.DisplayAlerts = True
        r_c1.Parent.Select
        i_reset = 1
        GoTo Reset
    End If
    'evaluate component, take different actions based on array boundaries
    On Error GoTo Fatality
    Select Case l_v_output_b_ubound
        Case 0
            'if 0 results require transposition (1+ columns, 1 row)
            Cells(10, l_c1_f_comp_i).Resize(UBound(v_c1_f_output)).Value = Application.Transpose(v_c1_f_output)
            l_c1_f_comp_i = l_c1_f_comp_i + 1
        Case 1
            '1+ rows, 1 column
            Cells(10, l_c1_f_comp_i).Resize(UBound(v_c1_f_output)).Value = v_c1_f_output
            l_c1_f_comp_i = l_c1_f_comp_i + 1
        Case Is > 1
            '1+ rows, 1+ columns
            'multi dimensional array so EITHER repeat evaluation but with SUM where SUM(components) = 1 or resize everything ?
            'base on number of components... if 1 return 1 answer
            Select Case i_c1_f_c
                Case 1
                    s_c1_f_comp = Replace(s_c1_f_comp, "ROW(1:1),", "ROW(1:1),SUM(") & ")"
                    v_c1_f_output = r_c1.Parent.Evaluate(s_c1_f_comp)
                    Cells(10, l_c1_f_comp_i).Resize(UBound(v_c1_f_output)).Value = v_c1_f_output
                    l_c1_f_comp_i = l_c1_f_comp_i + 1
                Case Else
                    'resize SPA sheet and write back multi dimensional values ?
                    'insert columns based on adjacent column to right of current column
                    For i_insert_col_i = 1 To (l_v_output_b_ubound - 1)
                        Columns(l_c1_f_comp_i + 1).Insert
                    Next i_insert_col_i
                    Cells(10, l_c1_f_comp_i).Resize(UBound(v_c1_f_output, 1), UBound(v_c1_f_output, 2)).Value = v_c1_f_output
                    'now completed insertion of code - adjust l_c1_f_comp_i counter such that next cell moved to contains next component (now moved)
                    l_c1_f_comp_i = l_c1_f_comp_i + i_insert_col_i
            End Select
    End Select
    'reset handler to default (for now...)
    On Error GoTo 0
Loop
'insert final column to total results
Cells(10, Columns.Count).End(xlToLeft).Offset(-1, 1).Value = "Total(s)"
'different totals depending on whether the component arrays > 1 column
'can check this by comparing:
'count of non-blanks in first row of results (10) (less 1 given col A populated with non array result)
'count of "Result" headers in header row (9)
'if match then arrays are single column/row arrays and can use a PRODUCT based approach
Select Case Application.WorksheetFunction.CountIf(Range("9:9"), "Result(s)") = Application.WorksheetFunction.CountA(Range("10:10")) - 1
    Case True
        Cells(10, 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]))"
    Case False
        'in these instances need to SUMPRODUCT the different arrays rather than PRODUCT the entire row
        'urgh... need to construct the formula on the fly given could have variable numbers of 1+ column arrays
        s_SPA_res_f = "=SUMPRODUCT("
        For i_SPA_res_i = 2 To (l_c1_f_comp_i - 1)
            Select Case UCase(Cells(9, i_SPA_res_i))
                Case ""
                    'column must be added to sum product so continue
                Case Else
                    'increment instances where RESULT found (ie commencement of component results)
                    i_SPA_res_cnt = i_SPA_res_cnt + 1
                    'must be commencement of new range
                    'close off first range in formula first (if necessary)
                    If i_SPA_res_cnt > 1 Then
                        s_SPA_res_f = s_SPA_res_f & "RC" & i_SPA_res_i - 1 & ","
                    End If
                    'create new range for SUMPRODUCT
                    s_SPA_res_f = s_SPA_res_f & "RC" & i_SPA_res_i & ":"
            End Select
        Next i_SPA_res_i
        'add last close to formula (given last header in range will be blank
        s_SPA_res_f = s_SPA_res_f & "RC" & i_SPA_res_i - 1 & ")"
        'insert formula across result range
        Cells(10, l_c1_f_comp_i).Resize(UBound(v_c1_f_output)).FormulaR1C1 = s_SPA_res_f
End Select
'totals column
With Cells(10, l_c1_f_comp_i).Resize(UBound(v_c1_f_output))
    'overwrite formulae with valuse (performance)
    .Formula = Cells(10, l_c1_f_comp_i).Resize(UBound(v_c1_f_output)).Value
    '.NumberFormat = "#,##0.0#;[Red](#,##0.0#);-"
    'bold total column
    .Font.Bold = True
End With
'-------------------------------------------------------------------------------------------------------------------------
'#STEP 5: FORMAT SPA SHEET
'-------------------------------------------------------------------------------------------------------------------------
'clean up excess id's in A (if reset invoked may have excess)
Range(Cells(Rows.Count, 2).End(xlUp).Offset(1, -1), Cells(Rows.Count, 1)).ClearContents
Columns(1).AutoFit
Range(Cells(5, 2), Cells(9, 2).End(xlToRight)).Columns.AutoFit
Cells(10, 1).Select
ActiveWindow.FreezePanes = True
'-------------------------------------------------------------------------------------------------------------------------
'#EXIT POINT
'-------------------------------------------------------------------------------------------------------------------------
ExitHere:
'-------------------------------------------------------------------------------------------------------------------------
'#RESET APP SETTINGS (based on store)
'-------------------------------------------------------------------------------------------------------------------------
With Application
    .ScreenUpdating = True
    Select Case l_calc
        Case -4105
            .Calculation = xlCalculationAutomatic
        Case -4135
            'no action (currently manual)
        Case 2
            .Calculation = xlCalculationSemiautomatic
    End Select
End With
'-------------------------------------------------------------------------------------------------------------------------
'#END
'-------------------------------------------------------------------------------------------------------------------------
Exit Sub

Fatality:
MsgBox "Fatal Error Occurred Processing Component Part", vbCritical, "Fatal Error"
If InStr(ActiveSheet.Name, "SPA_") Then
    Application.DisplayAlerts = False
    ActiveSheet.Delete
    Application.DisplayAlerts = True
    r_c1.Parent.Select
End If
Resume ExitHere

End Sub
 
Last edited:
Upvote 0
Yes reset is used to restart the process if mid way through processing a formula based on input delimiter etc it can be determined that the dimensions of the arrays generated by each component are not common -- the classic example of this was the:

=SUMPRODUCT(A1:A5*B1:F1)

If you put * as delimiter you will get an incorrect result obviously... if you put , as delimiter you will get a correct result... in the above instance the * is not a delimiter per se... the formula must be evaulated as one component.

Assuming user put * as delimiter the code would first split the formula down into parts, namely:

A1:A5 and B1:F1

It would evaluate and thus return A1:A5 prior to evaluating B1:F1... on evaluation of B1:F1 it would determine that the UBound value of the 2nd dimension would be 0 (1 to 5, nothing) whereas for the first component it was 1 (1 to 5, 1 to 1) ... thus in this case the formula can not be assessed in 2 parts as they are not of common "dimensions" and thus the formula must be reassessed in full delimiter-free -- ie evaluate A1:A5*B1:F1 as one calculation.

The "reset" is essentially invoked when the above occurs (ie the UBound value of 2nd dimension on any given array <> that of the very first component processed). When invoked the initial SPA sheet created is deleted and the formula is reprocessed in full delimiter-free so as to return correct result.

Does that clear things up at all ?


Absolutely, thanks.
 
Upvote 0
Re: mixed delimiters... having just posted reply to xld regards reset I think I'm actually making this more complex than need be... I think you can assume any/all of: , * ; to be delimiters where count of parentheses is 0... if * is not a true delimiter the "reset" will handle that anyway.

Please find reworked code below, xld I hope this resolves your issue ?

Notes:
I've left in the variable to hold the default delimiter purely for reset reasons.
The below now removes requirement for Application.InputBox to capture delimiter from user (a good thing IMO)

Haven't looked at this yet, but this is how I envisaged it, and what I alluded to in post #109 when I said

I am sure that the way is to determine the components regardless of the separator, by way of the parentheses count.
 
Upvote 0
Luke

Much better without the input box!

It doesn't seem to work on this example though:

Excel Workbook
ABCD
661111519
672121620
683131721
694141822
70
719020
Sheet1


Also, I'm not clear on what the Record column is doing?
 
Upvote 0
urgh... where do you dream these up Emma ?

Thanks though... a valid problem.

In this case the error is caused by the fact that on first evaluation (without user specifying delimiter) the formula is broken down into the various bits:

A66:A69; B66:D69; B66:D69

First component therefore generates a UBound value of 1 for 2nd dimension in array (1 to 4, 1 to 1)

The second component generates a UBound value of 3 for 2nd dimension in array (1 to 4, 1 to 3)

At this point the reset kicks in as it says this can't be a valid formula for a delimiter based approach given first and second components are not identical in dimension... it then re-evaluates the formula in one go:

The EVALUATE(A66:A69*B66:D69,B66:D69) only generates an array 1 row high -- ie the first row and returns 708 (should be 4 rows of 708, 1600, 2697, 4016 give or take the odd digit) ... so I think we're back to our issue of how the evaluate function is evaluating the above if we choose not to ignore the *...

If you used the old method and set delimiter to , (and ignored the *) you would get the correct result (can test by removing the * from the select case in step 3)
 
Last edited:
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