Forum Discussion

AmyM-NirR's avatar
AmyM-NirR
Copper Contributor
Jan 17, 2022
Solved

Max Running average

Hi, Excel 365 user over here.

I'm looking for a way to use dynamic array formulas to calculate the max of average sum, in one formula. Below is an example of max running average, where the average is for a period of every four consecutive cells:

I'm intending to use the FILTER function on the original data, thus I can't use the OFFSET function to calculate the max running average. How can I do so?

 

I thought about using the SEQUENCE function combined with ROW() function to create a dynamic array of running average (i.e. average of cells 1-2-3-4, 2-3-4-5, 3-4-5-6 etc. in the dynamic array of the original data), but unfortunately I wasn't successful.

 

Thanks everyone! 

  • AmyM-NirR I've used LET, SEQUENCE, TRANSPOSE and MMULT to accomplish this particular task. Not very straight-forward but it works.

    =LET(
        n, 4,
        array, myData,
        r, SEQUENCE(ROWS(array)),
        c, SEQUENCE(,ROWS(array)-n+1),
        mx, TRANSPOSE((r<=c+3)*(c<=r)),
        result, MMULT(mx,array)/n,
        result
    )

     

    File attached.

     

3 Replies

  • Riny_van_Eekelen's avatar
    Riny_van_Eekelen
    Platinum Contributor

    AmyM-NirR I've used LET, SEQUENCE, TRANSPOSE and MMULT to accomplish this particular task. Not very straight-forward but it works.

    =LET(
        n, 4,
        array, myData,
        r, SEQUENCE(ROWS(array)),
        c, SEQUENCE(,ROWS(array)-n+1),
        mx, TRANSPOSE((r<=c+3)*(c<=r)),
        result, MMULT(mx,array)/n,
        result
    )

     

    File attached.

     

Resources