Skip to main content
cancel
Showing results for 
Search instead for 
Did you mean: 

Register now to learn Fabric in free live sessions led by the best Microsoft experts. From Apr 16 to May 9, in English and Spanish.

Reply
tnwcloud
Regular Visitor

Display totals for parent item(s) in hierarchy when child selected

Working with a geo hierarchy Region>State>City. Have a measure that calculates Average Cost. Customer wants a report that allows them to select a City using a slicer and see the average cost for each level of the heirarchy on three separate cards. So in other words if they select 'Albany' in the slicer, the City card would show Average Cost for 'Albany', the State card for 'New York', and the Region card for 'Northeast'.

 

I've tinkered with VALUES and ALLEXCEPT thinking that I need to remove the lower hierarchy filters but I just can't get it. Any ideas?

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

Hi  @tnwcloud ,

I created some data:

vyangliumsft_0-1652341830485.png

Here are the steps you can follow:

1. Create measure.

City_Avg =
var _sleect=SELECTEDVALUE('Table'[City])
return
CALCULATE(AVERAGE('Table'[Amount]),FILTER(ALL('Table'),'Table'[City]=_sleect))
State_Avg =
var _select=SELECTEDVALUE('Table'[City])
var _status=CALCULATE(MAX('Table'[State]),FILTER(ALL('Table'),_select in SELECTCOLUMNS(FILTER(ALL('Table'),'Table'[State]=EARLIER('Table'[State])),"1",[City])))
return
CALCULATE(AVERAGE('Table'[Amount]),FILTER(ALL('Table'),'Table'[State]=_status))
Region_Avg =
var _select=SELECTEDVALUE('Table'[City])
var _status=CALCULATE(MAX('Table'[State]),FILTER(ALL('Table'),_select in SELECTCOLUMNS(FILTER(ALL('Table'),'Table'[State]=EARLIER('Table'[State])),"1",[City])))
var _region=CALCULATE(MAX('Table'[Region]),FILTER(ALL('Table'),_status in SELECTCOLUMNS(FILTER(ALL('Table'),'Table'[Region]=EARLIER('Table'[Region])),"1",[State])))
return
CALCULATE(AVERAGE('Table'[Amount]),FILTER(ALL('Table'),'Table'[Region]=_region)
)

2. Result:

vyangliumsft_1-1652341830487.png

 

Best Regards,

Liu Yang

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

3 REPLIES 3
v-yangliu-msft
Community Support
Community Support

Hi  @tnwcloud ,

I created some data:

vyangliumsft_0-1652341830485.png

Here are the steps you can follow:

1. Create measure.

City_Avg =
var _sleect=SELECTEDVALUE('Table'[City])
return
CALCULATE(AVERAGE('Table'[Amount]),FILTER(ALL('Table'),'Table'[City]=_sleect))
State_Avg =
var _select=SELECTEDVALUE('Table'[City])
var _status=CALCULATE(MAX('Table'[State]),FILTER(ALL('Table'),_select in SELECTCOLUMNS(FILTER(ALL('Table'),'Table'[State]=EARLIER('Table'[State])),"1",[City])))
return
CALCULATE(AVERAGE('Table'[Amount]),FILTER(ALL('Table'),'Table'[State]=_status))
Region_Avg =
var _select=SELECTEDVALUE('Table'[City])
var _status=CALCULATE(MAX('Table'[State]),FILTER(ALL('Table'),_select in SELECTCOLUMNS(FILTER(ALL('Table'),'Table'[State]=EARLIER('Table'[State])),"1",[City])))
var _region=CALCULATE(MAX('Table'[Region]),FILTER(ALL('Table'),_status in SELECTCOLUMNS(FILTER(ALL('Table'),'Table'[Region]=EARLIER('Table'[Region])),"1",[State])))
return
CALCULATE(AVERAGE('Table'[Amount]),FILTER(ALL('Table'),'Table'[Region]=_region)
)

2. Result:

vyangliumsft_1-1652341830487.png

 

Best Regards,

Liu Yang

If this post helps, then please consider Accept it as the solution to help the other members find it more quickly

tnwcloud
Regular Visitor

Thanks @amitchandak it worked for Region but not for State. Any idea why it might work for the top of the hierarchy but not lower down?

amitchandak
Super User
Super User

@tnwcloud , Measure for state , Assume you already have Avg Cost Measure

 

Meausre =

var _tab = summarize(allselected(Geo), Geo[State])

return

calculate([Avg Cost), filter(all(Geo), Geo[State] in _tab ) )

 

Meausre =

var _tab = summarize(allselected(Geo), Geo[Region])

return

calculate([Avg Cost), filter(all(Geo), Geo[Region] in _tab ) )

Helpful resources

Announcements
Microsoft Fabric Learn Together

Microsoft Fabric Learn Together

Covering the world! 9:00-10:30 AM Sydney, 4:00-5:30 PM CET (Paris/Berlin), 7:00-8:30 PM Mexico City

PBI_APRIL_CAROUSEL1

Power BI Monthly Update - April 2024

Check out the April 2024 Power BI update to learn about new features.

April Fabric Community Update

Fabric Community Update - April 2024

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