Reply
avatar user
Anonymous
Not applicable

Calculate average between double counting rows

Requested YearCustomer NameProjectProcessor NumberEcap Price ($)Ceiling VolumeWeightedEcap
2019BetaA1XXX1$770 204,000 157080000
2019ThetaA1XXX1$770 200,000 154000000
2019AlphaB1CCC2$1,650 102,000 168300000
2020Alpha2C1BBB2$1,5505077500

 

I have data in the above format and there is many more rows, what iam trying to do is essentially do a weighted average.

Where i made a measure that does

Average Ecap Price ($) = SUM(Table1[WeightedEcap]) / SUM(Table1[Ceiling Volume])
 
And this works fine.
 
However, I've come to realise in the data set I have I have double counting deals/rows. E.g Rows 1 and 2 in the example table above.
Where a deal has the same Year, Project, Sku, Ecap Price $ BUT Differnt Customer Name and Ceiling volume.
 
Instead I want to do this fromula (Average Ecap Price ($) = SUM(Table1[WeightedEcap]) / SUM(Table1[Ceiling Volume])) on the data set. But where there is double counting deals, I want to take the average of the ceiling volume e.g. average of 204,000 and 200,000 and multiple that by the ecap $770 once, to get the WeightedEcap column value, just once for each double counting deal.
 
Does anyone know how I could achieve this?
1 ACCEPTED SOLUTION
v-yiruan-msft
Community Support
Community Support

Hi @Anonymous ,

You can create a calculated column as below to get it, please find the details in the attachment.

WeightedEcap = 
VAR _avgcvol =
    CALCULATE (
        AVERAGE ( Table1[Ceiling Volume] ),
        FILTER (
            'Table1',
            'Table1'[Requested Year] = EARLIER ( Table1[Requested Year] )
                && 'Table1'[Project] = EARLIER ( 'Table1'[Project] )
                && 'Table1'[Processor Number] = EARLIER ( 'Table1'[Processor Number] )
        )
    )
RETURN
    _avgcvol * 'Table1'[Ecap Price ($)]

yingyinr_0-1667457241947.png

 

If the above one is not your expected result, please provide more raw data in your table with Text format and your expected result with backend logic and special examples. It is better if you can share a simplified pbix file. You can refer the following link to upload the file to the community. Thank you.

How to upload PBI in Community

Best Regards

Community Support Team _ Rena
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

1 REPLY 1
v-yiruan-msft
Community Support
Community Support

Hi @Anonymous ,

You can create a calculated column as below to get it, please find the details in the attachment.

WeightedEcap = 
VAR _avgcvol =
    CALCULATE (
        AVERAGE ( Table1[Ceiling Volume] ),
        FILTER (
            'Table1',
            'Table1'[Requested Year] = EARLIER ( Table1[Requested Year] )
                && 'Table1'[Project] = EARLIER ( 'Table1'[Project] )
                && 'Table1'[Processor Number] = EARLIER ( 'Table1'[Processor Number] )
        )
    )
RETURN
    _avgcvol * 'Table1'[Ecap Price ($)]

yingyinr_0-1667457241947.png

 

If the above one is not your expected result, please provide more raw data in your table with Text format and your expected result with backend logic and special examples. It is better if you can share a simplified pbix file. You can refer the following link to upload the file to the community. Thank you.

How to upload PBI in Community

Best Regards

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

Helpful resources

Announcements
March PBI video - carousel

Power BI Monthly Update - March 2025

Check out the March 2025 Power BI update to learn about new features.

March2025 Carousel

Fabric Community Update - March 2025

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

Top Solution Authors (Last Month)
Top Kudoed Authors (Last Month)