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
Anonymous
Not applicable

Price Benchmarking - Weighted Average

I am looking for some assistance to create a measure that results in a weighted average price for products that share a common variable - in this case, products that share a common age.

 

The weighted average should take into account not only the prices of all products with the same age, but also the ‘brand rankings’.

  • 70% bias towards rank 1 prices
  • 15% rank 2 prices
  • 15% rank 3 prices

To illustrate what I am seeking, please see the example below:

Annotation 2019-10-02 114337.png

As you can see, not all product ages have price examples from each of the brand ranks - the measure would need to be able to handle this.

 

I am unsure if this is something to tackle within the Excel file, or if we can achieve it in PowerBI. To assist, please see the following links for the Excel file and my attempts at a Power BI model.

 

LINK: Excel dataset

LINK: Power BI model

 

Can anyone help please? Thanks in advance.

1 ACCEPTED SOLUTION
vik0810
Resolver V
Resolver V

Hi, this measure should do it. Just add it to your table visualisation

 

Weighted Avg =
VAR SelectedAge =
    SELECTEDVALUE ( 'All Price Points'[Age] )
RETURN
    CALCULATE (
        DIVIDE (
            SUMX (
                'All Price Points',
                SWITCH ( RELATED ( 'BRAND RANKINGS'[Brand Rank] ), 1, 0.7, 2, 0.15, 3, 0.15 ) * 'All Price Points'[Price]
            ),
            SUMX (
                'All Price Points',
                SWITCH ( RELATED ( 'BRAND RANKINGS'[Brand Rank] ), 1, 0.7, 2, 0.15, 3, 0.15 )
            )
        ),
        ALL ( 'All Price Points' ),
        'All Price Points'[Age] = SelectedAge
    )

 

 

View solution in original post

2 REPLIES 2
vik0810
Resolver V
Resolver V

Hi, this measure should do it. Just add it to your table visualisation

 

Weighted Avg =
VAR SelectedAge =
    SELECTEDVALUE ( 'All Price Points'[Age] )
RETURN
    CALCULATE (
        DIVIDE (
            SUMX (
                'All Price Points',
                SWITCH ( RELATED ( 'BRAND RANKINGS'[Brand Rank] ), 1, 0.7, 2, 0.15, 3, 0.15 ) * 'All Price Points'[Price]
            ),
            SUMX (
                'All Price Points',
                SWITCH ( RELATED ( 'BRAND RANKINGS'[Brand Rank] ), 1, 0.7, 2, 0.15, 3, 0.15 )
            )
        ),
        ALL ( 'All Price Points' ),
        'All Price Points'[Age] = SelectedAge
    )

 

 

Anonymous
Not applicable

Thank you, @vik0810. Works perfectly.

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.