+ Reply to Thread
Results 1 to 5 of 5

Does a "averageproduct" exist that would work as a "sumproduct"?

  1. #1
    Registered User
    Join Date
    10-30-2014
    Location
    Riga
    MS-Off Ver
    Excel 2010
    Posts
    11

    Does a "averageproduct" exist that would work as a "sumproduct"?

    Hi guys,

    at the moment I am using sumproduct in a formula like this:

    SUMPRODUCT(DoD*(MONTH(DATE)=D$5)*(YEAR(DATE)=BL$5))

    DoD is a name for a column in another sheet that is defined dynamically by determining the name of the sheet: ( =INDIRECT(OW!$A13&"!y4"):INDEX(INDIRECT(OW!$A13&"!y:y");MATCH(10^10;INDIRECT(OW!$A13&"!y:y"))) )

    And of course D5 and BL5 make reference to a number relative to a month and a year.

    So basically the formula acts as a remote subtotal, by selecting a column in another sheet, within an interval of dates, and sum up the values.

    Question is, any idea how could I average these values instead of summing them up?

    I know I could just add another column in the target sheet full of "1", make a sumproduct of that too, and then divide the first one by this one, but I would gladly avoid creating a new column in the target sheets

    thank you in advance!

    Giovanni

  2. #2
    Forum Expert
    Join Date
    05-05-2015
    Location
    UK
    MS-Off Ver
    Microsoft? Excel? for Microsoft 365 MSO (Version 2402 Build 16.0.17328.20068) 64-bit
    Posts
    28,001

    Re: Does a "averageproduct" exist that would work as a "sumproduct"?

    Try

    SUMPRODUCT(DoD*(MONTH(DATE)=D$5)*(YEAR(DATE)=BL$5))/SUMPRODUCT(MONTH(DATE)=D$5)*(YEAR(DATE)=BL$5))

  3. #3
    Registered User
    Join Date
    10-30-2014
    Location
    Riga
    MS-Off Ver
    Excel 2010
    Posts
    11

    Re: Does a "averageproduct" exist that would work as a "sumproduct"?

    Brilliant! It was so easy actually, thank you!

  4. #4
    Forum Expert
    Join Date
    05-05-2015
    Location
    UK
    MS-Off Ver
    Microsoft? Excel? for Microsoft 365 MSO (Version 2402 Build 16.0.17328.20068) 64-bit
    Posts
    28,001

    Re: Does a "averageproduct" exist that would work as a "sumproduct"?

    You're welcome. Thank you for the feedback and rep.

  5. #5
    Forum Expert
    Join Date
    06-08-2012
    Location
    Left the forum!
    MS-Off Ver
    Left the forum!
    Posts
    5,189

    Re: Does a "averageproduct" exist that would work as a "sumproduct"?

    Another way

    =AVERAGEIFS(dod,date,">="&DATE(BL$5,D$5,1),date,"<="&EOMONTH(DATE(BL$5,D$5,1),0))

    =SUMIFS(dod,date,">="&DATE(BL$5,D$5,1),date,"<="&EOMONTH(DATE(BL$5,D$5,1),0))

    Both of which would more efficient if you have a large volume of data.

+ 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. Replies: 35
    Last Post: 01-13-2016, 02:16 AM
  2. Replies: 3
    Last Post: 01-02-2014, 02:15 PM
  3. Replies: 4
    Last Post: 11-17-2013, 12:05 PM
  4. [SOLVED] How to USE """"" cells count """"" change font color
    By austin123456 in forum Excel Programming / VBA / Macros
    Replies: 7
    Last Post: 10-09-2013, 06:14 AM
  5. Replies: 5
    Last Post: 10-12-2010, 06:46 AM
  6. Replies: 5
    Last Post: 06-26-2006, 09:23 PM
  7. Replies: 7
    Last Post: 05-13-2006, 05: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