cancel
Showing results for 
Search instead for 
Did you mean: 
Reply
JenaT Frequent Visitor
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

Accepted Solutions
Highlighted
Community Support Team
Community Support Team

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

 

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 Sheng
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.



For learning resources/Release notes, please visit: | |
3 REPLIES 3
Highlighted
Community Support Team
Community Support Team

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

 

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 Sheng
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.



For learning resources/Release notes, please visit: | |
JenaT Frequent Visitor
Frequent Visitor

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

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? 

Community Support Team
Community Support Team

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

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 Sheng
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.



For learning resources/Release notes, please visit: | |

Helpful resources

Announcements
Virtual Launch Event

Microsoft Business Applications October Virtual Launch Event

Join us for an in-depth look at the new innovations across Dynamics 365 and the Microsoft Power Platform.

Power BI Helps Homeless and Trouble Youth

Power BI Helps Homeless and Trouble Youth

We spoke with Power BI Super User, Greg Deckler, about his charity work

MBAS Gallery

Watch Sessions On Demand!

Continue your learning in our online communities.

Top Kudoed Authors
Users Online
Currently online: 260 members 2,955 guests
Please welcome our newest community members: