+ Reply to Thread
Results 1 to 7 of 7

Using SUMPRODUCT/ARRAY formula instead of helper column

  1. #1
    Forum Contributor
    Join Date
    07-13-2017
    Location
    Hong Kong
    MS-Off Ver
    MS Office 365
    Posts
    481

    Using SUMPRODUCT/ARRAY formula instead of helper column

    Hi all,

    I want to somehow simplify below formula to make it easier to maintain. I assume it could be written as a SUM/INDEX or SUMPRODUCT array formula instead?

    Please Login or Register  to view this content.
    See sample file attached... the red columns are the helper columns I want to get rid of, the yellow cells are the numbers I need to get to. I previously used the helper columns to get there, then removed them and created the looong formula above, which obviously makes it hard to maintain. Could someone have a look?
    Attached Files Attached Files

  2. #2
    Forum Guru
    Join Date
    03-02-2006
    Location
    Los Angeles, Ca
    MS-Off Ver
    WinXP/MSO2007;Win10/MSO2016
    Posts
    12,612

    Re: Using SUMPRODUCT/ARRAY formula instead of helper column

    Explain what that formula is calculating
    Ben Van Johnson

  3. #3
    Spammer
    Join Date
    01-08-2015
    Location
    Cali, Colombia
    MS-Off Ver
    365
    Posts
    302

    Re: Using SUMPRODUCT/ARRAY formula instead of helper column

    Hi, to all!

    You can use this array formula - you must enter in a single cell with Ctrl + Shift + Enter and not just enter:
    [BL6] : =SUM(IFERROR(INDEX(IA!D$3:AJ$410,N(IF(1,ROW(IA!A$3:A$410)-ROW(IA!A$2))),N(IF(1,MATCH(E$5:AG$5,IA!D$2:AJ$2,)))),)*(E6:AG6="x")*(IA!C$3:C$410=C6)*(IA!A$3:A$410=E$1)*(IA!B$3:B$410=D6)*E$2:AG$2)

    And drag it down.

    P.D: With this formula, don't use whole columns. Instead, you can use a bigger number of your average row of data.

    Blessings!
    Last edited by johnmpl; 01-22-2018 at 04:21 PM.

  4. #4
    Forum Expert daddylonglegs's Avatar
    Join Date
    01-14-2006
    Location
    England
    MS-Off Ver
    2016
    Posts
    14,675

    Re: Using SUMPRODUCT/ARRAY formula instead of helper column

    Try this regular formula in row 6 copied down

    =SUMPRODUCT(SUMIFS(E$2:AG$2,E$5:AG$5,IA!D$2:AJ$2,E6:AG6,"<>")*(IA!A$3:A$1000=E$1)*(IA!C$3:C$1000=C6)*(IA!B$3:B$1000=D6),IA!D$3:AJ$1000)
    Last edited by daddylonglegs; 01-22-2018 at 08:44 PM.
    Audere est facere

  5. #5
    Forum Contributor
    Join Date
    07-13-2017
    Location
    Hong Kong
    MS-Off Ver
    MS Office 365
    Posts
    481

    Re: Using SUMPRODUCT/ARRAY formula instead of helper column

    Thanks! Both formulas work, however they are very inefficient compared to my overly long original formula. Is there a way to slightly rewrite it to speed it up? Calculation times are at least 20 times slower

  6. #6
    Spammer
    Join Date
    01-08-2015
    Location
    Cali, Colombia
    MS-Off Ver
    365
    Posts
    302

    Re: Using SUMPRODUCT/ARRAY formula instead of helper column

    Hi, esbencito!

    daddylonglegs formula is faster and shorter than mine. And it's not true that the Calculation times are at least 20 times slower. I make some tests, and these were my results:

    0.31672 --> Time with helpers
    0.30832 --> Time with your long formula

    1.261 --> John's Formula (till row 410).
    0.834 --> Daddy's Formula (till row 1000).
    0.414 --> Daddy's Formula (till row 410).

    If you reduce the rows of Daddy's formula to 410, This reduce the time more than a half!

    Recommendation --> Select Range A2 to AJ410 and convert to table (Insert - Table or Ctrl + T). This way you have dynamic ranges, and formulas adjust to your data without any range formulation and other technics. Blessings!

  7. #7
    Forum Contributor
    Join Date
    07-13-2017
    Location
    Hong Kong
    MS-Off Ver
    MS Office 365
    Posts
    481

    Re: Using SUMPRODUCT/ARRAY formula instead of helper column

    Hi johnmpl,

    I just tested it again, and it reduces calculation times indeed by half if only range A2:AJ410 is selected. Though, it is still significantly slower than my overly long formula. See calculation times for comparison below:

    Formula with helper columns:

    HelperColumns.PNG

    My original long formula:

    INDEXMATCH.PNG

    Daddy's SUMPRODUCT formula:

    SUMPRODUCT.PNG

+ Reply to Thread

Thread Information

Users Browsing this Thread

There are currently 1 users browsing this thread. (0 members and 1 guests)

Similar Threads

  1. [SOLVED] Adapt array formula to remove need for helper row
    By JayUSA in forum Excel General
    Replies: 2
    Last Post: 09-20-2017, 10:56 PM
  2. A Simple Formula/Helper Column To Transpose a Range
    By chullan88 in forum Excel Formulas & Functions
    Replies: 15
    Last Post: 10-24-2016, 09:09 AM
  3. [SOLVED] Fill down dates overwriting times ( vba ) or by adding a helper column with formula
    By Kerryx in forum Excel Formulas & Functions
    Replies: 11
    Last Post: 09-23-2016, 06:14 AM
  4. Sort by helper column even if values in helper are alike
    By NoSleepForMe in forum Excel Formulas & Functions
    Replies: 4
    Last Post: 08-10-2016, 04:14 AM
  5. [SOLVED] Using array formula instead of creating a helper column
    By jasonleewkd in forum Excel Formulas & Functions
    Replies: 8
    Last Post: 11-10-2014, 12:55 PM
  6. Array Formulas instead of helper columns
    By ElmerS in forum Excel Formulas & Functions
    Replies: 15
    Last Post: 11-25-2009, 03:52 PM
  7. Modify Sumproduct to include helper column
    By JDarling in forum Excel Formulas & Functions
    Replies: 11
    Last Post: 12-17-2007, 06:03 PM

Tags for this Thread

Bookmarks

Posting Permissions

  • You may not post new threads
  • You may not post replies
  • You may not post attachments
  • You may not edit your posts

Search Engine Friendly URLs by vBSEO 3.6.0 RC 1