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
JenaT
Frequent Visitor

Measure with average for first row and repeated value for next rows based on multiple conditions

Hi, everyone!

 

I have been struggling for a while to make a measure that would give me a result as shown in the picture below.

Basically, if there is an event then calculate the average for 'selected what-if value' number of days for the event's first date (yellow) and for the next days give the same values (orange). Events should be excluded from average calculation, every Product-Client should be calculated separately (event names may repeat).

 Capture.JPG

 

 

 

The last formula I was at is below. Unfortunately, it gave the wrong average calculation, 

Base =
IF (
    ISBLANK (
        CALCULATE (
            FIRSTNONBLANK ( 'Sales'[Event], 'Sales'[Event] ),
            FILTER ( ALL ( 'Sales'[Event] ), 'Sales'[Event] <> BLANK () )
        )
    ),
    SUMX ( 'Sales', 'Sales'[Volume] ),
    SUMX (
        'Sales',
        CALCULATE (
            AVERAGEX ( 'Sales', 'Sales'[Volume] ),
            DATESINPERIOD (
                'Sales'[Date],
                LASTDATE ( 'Sales'[Date].[Date] )-1,
                - SELECTEDVALUE ( 'What-if value'[Value], 7 ),
                DAY
            ),
            FILTER (
                ALLEXCEPT ( 'Sales', 'Sales'[Client], 'Sales'[Product] ),
                'Sales'[Event] = BLANK ()
            )
        )
    )
)

 

Thank you very much for your help!

1 ACCEPTED SOLUTION
v-shex-msft
Community Support
Community Support

 

Hi @JenaT,

 

You can try to use below measure formula to achieve your requirement:

 

Dynamic Avg = 
VAR CurrProduct =
    FIRSTNONBLANK ( Sales[Product], [Product] )
VAR currClient =
    FIRSTNONBLANK ( Sales[Client], [Client] )
VAR currEvent =
    SELECTEDVALUE ( Sales[Event] ) 
VAR filtered =
    FILTER (
        ALLSELECTED ( Sales ),
        [Event] = BLANK ()
            && [Product] = CurrProduct
            && [Client] = currClient
            && [Date] < MAX ( Sales[Date] )
    )
RETURN
    IF (
        currEvent <> BLANK (),
        AVERAGEX (
            FILTER (
                ADDCOLUMNS (
                    filtered,
                    "DESC Index", COUNTX ( FILTER ( filtered, [Date] >= EARLIER ( [Date] ) ), [Date] )
                ),
                [DESC Index] <= SELECTEDVALUE ( 'What-if value'[What-if value] )
            ),
            [Volume]
        )
    )

 41.gif

 

Measure used to display correspondent records.

 

Correspond Items = 
VAR CurrProduct =
    FIRSTNONBLANK ( Sales[Product], [Product] )
VAR currClient =
    FIRSTNONBLANK ( Sales[Client], [Client] )
VAR currEvent =
    SELECTEDVALUE ( Sales[Event] )
VAR filtered =
    FILTER (
        ALLSELECTED ( Sales ),
        [Event] = BLANK ()
            && [Product] = CurrProduct
            && [Client] = currClient
            && [Date] < MAX ( Sales[Date] )
    )
RETURN
    IF (
        currEvent <> BLANK (),
        CONCATENATEX (
            FILTER (
                ADDCOLUMNS (
                    filtered,
                    "DESC Index", COUNTX ( FILTER ( filtered, [Date] >= EARLIER ( [Date] ) ), [Date] )
                ),
                [DESC Index] <= SELECTEDVALUE ( 'What-if value'[What-if value] )
            ),
            [Volume],
            ","
        )
    )

 

Regards,

Xiaoxin Sheng

Community Support Team _ Xiaoxin
If this post helps, please consider accept as solution to help other members find it more quickly.

View solution in original post

3 REPLIES 3
v-shex-msft
Community Support
Community Support

 

Hi @JenaT,

 

You can try to use below measure formula to achieve your requirement:

 

Dynamic Avg = 
VAR CurrProduct =
    FIRSTNONBLANK ( Sales[Product], [Product] )
VAR currClient =
    FIRSTNONBLANK ( Sales[Client], [Client] )
VAR currEvent =
    SELECTEDVALUE ( Sales[Event] ) 
VAR filtered =
    FILTER (
        ALLSELECTED ( Sales ),
        [Event] = BLANK ()
            && [Product] = CurrProduct
            && [Client] = currClient
            && [Date] < MAX ( Sales[Date] )
    )
RETURN
    IF (
        currEvent <> BLANK (),
        AVERAGEX (
            FILTER (
                ADDCOLUMNS (
                    filtered,
                    "DESC Index", COUNTX ( FILTER ( filtered, [Date] >= EARLIER ( [Date] ) ), [Date] )
                ),
                [DESC Index] <= SELECTEDVALUE ( 'What-if value'[What-if value] )
            ),
            [Volume]
        )
    )

 41.gif

 

Measure used to display correspondent records.

 

Correspond Items = 
VAR CurrProduct =
    FIRSTNONBLANK ( Sales[Product], [Product] )
VAR currClient =
    FIRSTNONBLANK ( Sales[Client], [Client] )
VAR currEvent =
    SELECTEDVALUE ( Sales[Event] )
VAR filtered =
    FILTER (
        ALLSELECTED ( Sales ),
        [Event] = BLANK ()
            && [Product] = CurrProduct
            && [Client] = currClient
            && [Date] < MAX ( Sales[Date] )
    )
RETURN
    IF (
        currEvent <> BLANK (),
        CONCATENATEX (
            FILTER (
                ADDCOLUMNS (
                    filtered,
                    "DESC Index", COUNTX ( FILTER ( filtered, [Date] >= EARLIER ( [Date] ) ), [Date] )
                ),
                [DESC Index] <= SELECTEDVALUE ( 'What-if value'[What-if value] )
            ),
            [Volume],
            ","
        )
    )

 

Regards,

Xiaoxin Sheng

Community Support Team _ Xiaoxin
If this post helps, please consider accept as solution to help other members find it more quickly.

Thanks!

 

The Dynamic Avg works well as long as Client and Product are both listed in the table. However, if I remove Product column and the Product data is aggregated (e.g. there are several products with Promo1 in the same period), then the averages are not aggregated and the value for Product1 is again shown. Is there a workaround for this? 

Hi @JenaT,

 

You can try to remove currProduct condition from measure:

Dynamic Avg = 
VAR currClient =
    FIRSTNONBLANK ( Sales[Client], [Client] )
VAR currEvent =
    SELECTEDVALUE ( Sales[Event] ) 
VAR filtered =
    FILTER (
        ALLSELECTED ( Sales ),
        [Event] = BLANK ()
            && [Client] = currClient
            && [Date] < MAX ( Sales[Date] )
    )
RETURN
    IF (
        currEvent <> BLANK (),
        AVERAGEX (
            FILTER (
                ADDCOLUMNS (
                    filtered,
                    "DESC Index", COUNTX ( FILTER ( filtered, [Date] >= EARLIER ( [Date] ) ), [Date] )
                ),
                [DESC Index] <= SELECTEDVALUE ( 'What-if value'[What-if value] )
            ),
            [Volume]
        )
    )

 

Regards,

Xiaoxin Sheng

Community Support Team _ Xiaoxin
If this post helps, please consider accept as solution to help 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.