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

Be one of the first to start using Fabric Databases. View on-demand sessions with database experts and the Microsoft product team to learn just how easy it is to get started. Watch now

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 ) )

Join us as experts from around the world come together to shape the future of data and AI!
At the Microsoft Analytics Community Conference, global leaders and influential voices are stepping up to share their knowledge and help you master the latest in Microsoft Fabric, Copilot, and Purview.
️ November 12th-14th, 2024
 Online Event
Register Here

Helpful resources

Announcements
Las Vegas 2025

Join us at the Microsoft Fabric Community Conference

March 31 - April 2, 2025, in Las Vegas, Nevada. Use code MSCUST for a $150 discount!

November Carousel

Fabric Community Update - November 2024

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

Dec Fabric Community Survey

We want your feedback!

Your insights matter. That’s why we created a quick survey to learn about your experience finding answers to technical questions.