+ Reply to Thread
Results 1 to 10 of 10

Decoding an excel formula on sumproduct

  1. #1
    Registered User
    Join Date
    12-16-2021
    Location
    Madison
    MS-Off Ver
    365
    Posts
    6

    Lightbulb Decoding an excel formula on sumproduct

    Hello Everybody,

    This is my first post in this forum and I need help with an excel formula in a worksheet. It is a 'sumproduct' but I am not able to decode which rows and columns are linked in the formula because of the 'indirect function' used. The formula is:

    Sumproduct(Inventory!C$3:InventoryC7,INDIRECT(ADDRESS(FC!$A$2006)-Inventory!$A7+1,Column(FCB$4),,,"FC")):FC!B$2006)

    Here sumproduct in a sheet is calculated using data from two sheets 'inventory' and 'FC'.

    I would be really grateful if someone can help me in understanding which rows of 'FC' sheet are multiplied with the rows C3:C7 in the 'Inventory' sheet.

    Kind regards,
    Poonam
    Last edited by PoonamKhatri; 12-16-2021 at 01:56 PM.

  2. #2
    Forum Moderator Glenn Kennedy's Avatar
    Join Date
    07-08-2012
    Location
    Digital Nomad... occasionally based in Ireland.
    MS-Off Ver
    O365 (PC) V 2406
    Posts
    44,662

    Re: Decoding an excel formula on sumproduct

    Hi there.

    A picture is worth 1,000 words. An Excel sheet is worth 1,000 non-editable pictures.

    Please read the yellow banner about sample worksheets, at the top of the screen. Act on its guidelines and post a SMALL sample sheet complete with an explanation and some expected results.
    Glenn




    None of us get paid for helping you... we do this for fun. So DON'T FORGET to say "Thank You" to all who have freely given some of their time to help YOU

  3. #3
    Registered User
    Join Date
    12-16-2021
    Location
    Madison
    MS-Off Ver
    365
    Posts
    6

    Re: Decoding an excel formula on sumproduct

    Hi Glenn, I have a sample sheet that can make you understand my question better and you may help me.
    Attached Files Attached Files

  4. #4
    Registered User
    Join Date
    12-16-2021
    Location
    Madison
    MS-Off Ver
    365
    Posts
    6

    Re: Decoding an excel formula on sumproduct

    Waiting for help in decoding an excel function.

  5. #5
    Forum Moderator AliGW's Avatar
    Join Date
    08-10-2013
    Location
    Retired in Ipswich, Suffolk, but grew up in Sawley, Derbyshire (both in England)
    MS-Off Ver
    MS 365 Subscription Insider Beta Channel v. 2503 (Windows 11 Home 24H2 64-bit)
    Posts
    90,310

    Re: Decoding an excel formula on sumproduct

    Administrative Note:

    We don't expect you to bump threads sooner than 24 hours after your last post or more than once a day. Please remember that those who help here do so voluntarily and of their own goodwill. They live in many different time zones and many will be out at work right now if they are not asleep on the other side of the globe. This is not a paid 'service': members will help when they are ready and able to do so, and not 'on demand'. If you get the help you need today, that's fine, but you really should not count on it. Thanks for your understanding and patience.
    Ali


    Enthusiastic self-taught user of MS Excel who's always learning!
    Don't forget to say "thank you" in your thread to anyone who has offered you help. It's a universal courtesy.
    You can reward them by clicking on * Add Reputation below their user name on the left, if you wish.

    NB:
    as a Moderator, I never accept friendship requests.
    Forum Rules (updated August 2023): please read them here.

  6. #6
    Registered User
    Join Date
    12-16-2021
    Location
    Madison
    MS-Off Ver
    365
    Posts
    6

    Re: Decoding an excel formula on sumproduct

    Hi Ali,

    Sorry and thank you for your note. I am new to this forum. Pardon me for being impatient with the answer to my first post. I will follow your advice for next time.

    Kind regards,
    Poonam

  7. #7
    Valued Forum Contributor
    Join Date
    04-13-2011
    Location
    Ottawa, Canada
    MS-Off Ver
    365
    Posts
    1,101

    Re: Decoding an excel formula on sumproduct

    Hi PoonamKhatri,

    There's an error on your formula that you post on the thread...so a little correction here and also the explanation of the SUMPRODUCT formula.

    Please Login or Register  to view this content.
    Breakdown of formula and it's result:

    Inventory!C$3:Inventory!C7: Look at the range of C3:C7 in [Inventory] sheet. Result in {5;10;10;10;10}

    ROW(FC!$A$2006): Returns the row index in cell A2006 in [FC] sheet. Result in 2006 (because A1 is row 1, A100 is row 100, thus A2006 is 2006)

    COLUMN(FC!B$4): Returns the column index in cell B4 in [FC] sheet. Result in 2 (because column A is 1, column B is 2)

    ADDRESS function has the following properties:
    ADDRESS(row_num, column_num, [abs_num],[a1], [sheet_text]) - here row_num and column_num is mandatory, and the rest are optional.

    Given that
    ADDRESS(ROW(FC!$A$2006)-Inventory!$A7+1,COLUMN(FC!B$4),,,"FC"), and we know that the ROW() and COLUMN(), it thus becomes
    ADDRESS(2006-Inventory!$A7+1,2,,,"FC") which simplifies further to
    ADDRESS(2006-5+1,2,,,"FC") which simplifies further to
    ADDRESS(2002,2,,,"FC").
    And finally reads as "FC!$B$2002". Note that at this point this is only a text or string. Not an Excel Range.

    This then gets put into the INDIRECT function:
    INDIRECT(ADDRESS(...)) technically ask INDIRECT function to turn the string that we derived from ADDRESS function into an excel range.

    And finally it turns into a range that is used for the SUMPRODUCT:

    SUMPRODUCT(Inventory!C$3:Inventory!C7, INDIRECT("FC!$B$2002"):FC!B$2006) notice that double quote
    SUMPRODUCT(Inventory!C$3:Inventory!C7, FC!$B$2002:FC!B$2006) and thus becomes
    {5;10;10;10;10} * {1.38E-15; 1.43E-15, 1.5E-15, 1.59E-15, 1.69E-15}
    Last edited by dluhut; 12-16-2021 at 07:07 PM.

  8. #8
    Registered User
    Join Date
    12-16-2021
    Location
    Madison
    MS-Off Ver
    365
    Posts
    6

    Re: Decoding an excel formula on sumproduct

    Thank you so much for this detailed decoding. I would sincerely appreciate if you can simplify further on how you decoded the address of rows and column to reach this: FC!$B$2002.

    I need to understand so that I can recreate a similar formula that I can drag down.

    Thank you,

    Poonam

  9. #9
    Forum Moderator Glenn Kennedy's Avatar
    Join Date
    07-08-2012
    Location
    Digital Nomad... occasionally based in Ireland.
    MS-Off Ver
    O365 (PC) V 2406
    Posts
    44,662

    Re: Decoding an excel formula on sumproduct

    It strikes me that it's a very messy formula!!

    To help you understand, I have CUT IT BACK to a sample (10-20 rows, as requested) and simplified it with small integers.

    In the first row it is multiplying the first ONE value on Inventory by the last value on FC and summing the result (as there's only one result... that doesn't happen... obviously)
    In the second row it is multiplying the first TWO values on Inventory by the last TWO values on FC and summing the result
    In the third row it is multiplying the first THREE values on Inventory by the last THREE values on FC and summing the result
    and so on.

    It is HORRIBLY inefficient.

    Use this instead:

    =SUMPRODUCT(Inventory!C$3:Inventory!C3,FC!$B$26:INDEX(FC!$B:$B,AGGREGATE(14,6,ROW(FC!$B$7:$B$26),COUNT($A$4:A4))))

    change the bits in red to reflect the last data row in your real sample. Drag down.

    With a small sample (now...) you can use formulas/formula auditing/evaluate formula to see what is happening. That is impossible with 2000+ rows.
    Attached Files Attached Files

  10. #10
    Registered User
    Join Date
    12-16-2021
    Location
    Madison
    MS-Off Ver
    365
    Posts
    6

    Re: Decoding an excel formula on sumproduct

    Thank you so much Glen! I really appreciate this help

+ 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] Vlookup formula Decoding help needed...
    By swade730 in forum Excel Programming / VBA / Macros
    Replies: 3
    Last Post: 09-29-2014, 03:56 PM
  2. decoding formula assistance
    By eehimes in forum Excel Formulas & Functions
    Replies: 2
    Last Post: 07-31-2014, 01:44 PM
  3. Replies: 2
    Last Post: 06-20-2014, 12:42 PM
  4. Decoding an excel formula
    By nadeemsmarty in forum Excel Formulas & Functions
    Replies: 2
    Last Post: 05-12-2014, 01:15 PM
  5. Encoding-Decoding
    By laxmanann in forum Excel Programming / VBA / Macros
    Replies: 7
    Last Post: 05-09-2014, 02:33 AM
  6. Base64 decoding using excel function
    By deepak1986 in forum Excel Formulas & Functions
    Replies: 2
    Last Post: 04-20-2012, 02:21 PM
  7. decoding formula issue
    By Ricersux in forum Excel General
    Replies: 1
    Last Post: 02-18-2008, 12:02 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