Skip to main content
cancel
Showing results for 
Search instead for 
Did you mean: 

Earn the coveted Fabric Analytics Engineer certification. 100% off your exam for a limited time only!

Reply
thollitez
Regular Visitor

Need help SUM or AVERAGE last 7 Previous Records (Not Using Date)

Hi Guys,

 

I've been checking the forum and google regarding SUM or AVERAGE last specific number of records.

All solutions i've found is using DATE, but DATE is irrelevant on what i am trying to attain.

 

What i am really trying to attain is get the AVERAGE of last 7 records regardless of the dates.

 

Please see example below.

 Capture.PNG

 

Thanks in advance.

 

1 ACCEPTED SOLUTION
v-piga-msft
Resident Rockstar
Resident Rockstar

Hi @thollitez,

 

For your scenario, you should create an index column in Query Editor and create the measure below.

 

1. Create Index column

 

add index.PNG

 

2. Create the measure under Modeling tab.

Moving Average last 7 Records =
VAR SevenrecordsTotal =
    CALCULATE (
        SUM ( 'table'[UNITS SOLD] ),
        FILTER (
            ALL ( 'table'[Index] ),
            'table'[Index] <= MAX ( 'table'[Index] )
                && 'table'[Index]
                    >= MAX ( 'table'[Index] ) - 6
        ),
        ALL ( 'table' )
    )
VAR Records =
    CALCULATE (
        DISTINCTCOUNT ( 'table'[Index] ),
        FILTER (
            ALL ( 'table'[Index] ),
            'table'[Index] <= MAX ( 'table'[Index] )
                && 'table'[Index]
                    >= MAX ( 'table'[Index] ) - 6
                && 'table'[Index] <> BLANK ()
        ),
        ALL ( 'table' )
    )
RETURN
    IF ( SUM ( 'table'[Index] ) >= 7, DIVIDE ( SevenrecordsTotal, Records ), BLANK () )

 

 

Then you could get the output below.

average last 7 records.PNG

 

You also could refer to the attached pbix

 

Best Regards,

Cherry

Community Support Team _ Cherry Gao
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.

View solution in original post

3 REPLIES 3
v-piga-msft
Resident Rockstar
Resident Rockstar

Hi @thollitez,

 

For your scenario, you should create an index column in Query Editor and create the measure below.

 

1. Create Index column

 

add index.PNG

 

2. Create the measure under Modeling tab.

Moving Average last 7 Records =
VAR SevenrecordsTotal =
    CALCULATE (
        SUM ( 'table'[UNITS SOLD] ),
        FILTER (
            ALL ( 'table'[Index] ),
            'table'[Index] <= MAX ( 'table'[Index] )
                && 'table'[Index]
                    >= MAX ( 'table'[Index] ) - 6
        ),
        ALL ( 'table' )
    )
VAR Records =
    CALCULATE (
        DISTINCTCOUNT ( 'table'[Index] ),
        FILTER (
            ALL ( 'table'[Index] ),
            'table'[Index] <= MAX ( 'table'[Index] )
                && 'table'[Index]
                    >= MAX ( 'table'[Index] ) - 6
                && 'table'[Index] <> BLANK ()
        ),
        ALL ( 'table' )
    )
RETURN
    IF ( SUM ( 'table'[Index] ) >= 7, DIVIDE ( SevenrecordsTotal, Records ), BLANK () )

 

 

Then you could get the output below.

average last 7 records.PNG

 

You also could refer to the attached pbix

 

Best Regards,

Cherry

Community Support Team _ Cherry Gao
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.

Thank you very much sir v-piga-msft, it really solved my problem.

 

You're the best.

Hi @thollitez,

 

It's glad that we can help. You're welcome.Smiley Very Happy

 

Best Regards,

Cherry

Community Support Team _ Cherry Gao
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.

Helpful resources

Announcements
April AMA free

Microsoft Fabric AMA Livestream

Join us Tuesday, April 09, 9:00 – 10:00 AM PST for a live, expert-led Q&A session on all things Microsoft Fabric!

March Fabric Community Update

Fabric Community Update - March 2024

Find out what's new and trending in the Fabric Community.