Microsoft Fabric Community Conference 2025, March 31 - April 2, Las Vegas, Nevada. Use code MSCUST for a $150 discount.
Register nowThe Power BI DataViz World Championships are on! With four chances to enter, you could win a spot in the LIVE Grand Finale in Las Vegas. Show off your skills.
hi,
i have a table below. I want to calculate avg of ProductsPurchased of all other rows except current row. And there is filter Year.
ex: for first row in below table, 'Avg of all others' should be the below value ( avg of 200+25+100 for year 2016).
Please help.
Year Customer ProductsPurchased Avg of all others
2016 A 225 108.3
Year CustomerProductPurchased
2016 | A | 225 |
2016 | B | 200 |
2016 | C | 25 |
2016 | D | 100 |
2015 | A | 158 |
2015 | B | 150 |
2015 | C | 30 |
2015 | D | 90 |
Solved! Go to Solution.
Hi @srk_powerbi ,
Create a measure like this:
Measure = var cur_cus = MAX('Table'[Customer])
return
CALCULATE(AVERAGE('Table'[sales]),FILTER(ALLEXCEPT('Table','Table'[Year]),'Table'[Customer]<>cur_cus))
Best Regards,
Liang
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.
@Greg_Deckler thanks. the calculated column you provided above gives me the sum. Now how can i calculate avg?
Also, can i do the same by creating a Measure inst?ead of calculated column?
Hi @srk_powerbi ,
Create a measure like this:
Measure = var cur_cus = MAX('Table'[Customer])
return
CALCULATE(AVERAGE('Table'[sales]),FILTER(ALLEXCEPT('Table','Table'[Year]),'Table'[Customer]<>cur_cus))
Best Regards,
Liang
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.
@srk_powerbi If you add an ID column in Power Query then this should be easier and more certain. Otherwise you can use variables or EARLIER to identify rows other than the current row. See my article on Mean Time Between Failure (MTBF) which uses EARLIER: http://community.powerbi.com/t5/Community-Blog/Mean-Time-Between-Failure-MTBF-and-Power-BI/ba-p/3395....
The basic pattern is:
Column =
VAR __Current = [Value]
VAR __PreviousDate = MAXX(FILTER('Table','Table'[Date] < EARLIER('Table'[Date])),[Date])
VAR __Previous = MAXX(FILTER('Table',[Date]=__PreviousDate),[Value])
RETURN
__Current - __Previous
In your case, you could do something like:
Column = SUMX(FILTER('Table',[Year]=EARLIER([Year]) && [Customer]<>EARLIER([Customer])),[ProductPurchased)
User | Count |
---|---|
123 | |
69 | |
67 | |
58 | |
52 |
User | Count |
---|---|
183 | |
90 | |
67 | |
62 | |
53 |