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

Get Fabric Certified for FREE during Fabric Data Days. Don't miss your chance! Request now

Reply
ys034
Helper I
Helper I

create right hierarchy filter for Continent, Region, Country

I have the following data fou our use case:

ys034_0-1664960857824.png

 

We have market shares for countries as well as consolidated regions. Our "pain" is that we have all the data in the same column

We would like to create a hierarchy that is structured as follows:

World = World
EU = France, Germany, Russia, Turkey, Ukraine, United Kingdom
WEU = France, Germany, United Kingdom
EEU = Turkey, Ukraine, Russia

 

the final result in Power BI (Filter) should look like this

 

ys034_1-1664960857522.png

 

 

 

 

At the end, the market shares should not be aggregated when filtering, but should refer to the market share provided in the column.

 

I would be grateful for any help!

1 ACCEPTED SOLUTION
Anonymous
Not applicable

Hi @ys034 ,

 

I suggest you to create a calculated table for hierarchy level.

Table 2 = 
SELECTCOLUMNS (
    FILTER (
        VALUES ( 'Table'[Region] ),
        NOT ( [Region] IN { "World", "EU", "WEU", "EEU" } )
    ),
    "Level1", "World",
    "Level2", "EU",
    "Level3",
        IF (
            'Table'[Region] IN { "France", "Germany", "United Kingdom" },
            "WEU",
            "EEU"
        ),
    "Level4",'Table'[Region]
)

Table2 looks like as below.

RicoZhou_0-1665042423104.png

Then create a meause.

Measure = 
VAR _LEVEL1 = CALCULATE(SUM('Table'[Market Share]),FILTER(ALL('Table'),'Table'[Region] = MAX('Table 2'[Level1])))
VAR _LEVEL2= CALCULATE(SUM('Table'[Market Share]),FILTER(ALL('Table'),'Table'[Region] = MAX('Table 2'[Level2])))
VAR _LEVEL3= CALCULATE(SUM('Table'[Market Share]),FILTER(ALL('Table'),'Table'[Region] = MAX('Table 2'[Level3])))
VAR _LEVEL4 =CALCULATE(SUM('Table'[Market Share]),FILTER(ALL('Table'),'Table'[Region] = MAX('Table 2'[Level4])))
RETURN
IF(ISINSCOPE('Table 2'[Level4]),_LEVEL4,IF(ISINSCOPE('Table 2'[Level3]),_LEVEL3,IF(ISINSCOPE('Table 2'[Level2]),_LEVEL2,IF(ISINSCOPE('Table 2'[Level1]),_LEVEL1,SUM('Table'[Market Share])))))

Result is as below.

RicoZhou_2-1665042798855.png

 

Best Regards,
Rico Zhou

 

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

Hi @ys034 ,

 

I suggest you to create a calculated table for hierarchy level.

Table 2 = 
SELECTCOLUMNS (
    FILTER (
        VALUES ( 'Table'[Region] ),
        NOT ( [Region] IN { "World", "EU", "WEU", "EEU" } )
    ),
    "Level1", "World",
    "Level2", "EU",
    "Level3",
        IF (
            'Table'[Region] IN { "France", "Germany", "United Kingdom" },
            "WEU",
            "EEU"
        ),
    "Level4",'Table'[Region]
)

Table2 looks like as below.

RicoZhou_0-1665042423104.png

Then create a meause.

Measure = 
VAR _LEVEL1 = CALCULATE(SUM('Table'[Market Share]),FILTER(ALL('Table'),'Table'[Region] = MAX('Table 2'[Level1])))
VAR _LEVEL2= CALCULATE(SUM('Table'[Market Share]),FILTER(ALL('Table'),'Table'[Region] = MAX('Table 2'[Level2])))
VAR _LEVEL3= CALCULATE(SUM('Table'[Market Share]),FILTER(ALL('Table'),'Table'[Region] = MAX('Table 2'[Level3])))
VAR _LEVEL4 =CALCULATE(SUM('Table'[Market Share]),FILTER(ALL('Table'),'Table'[Region] = MAX('Table 2'[Level4])))
RETURN
IF(ISINSCOPE('Table 2'[Level4]),_LEVEL4,IF(ISINSCOPE('Table 2'[Level3]),_LEVEL3,IF(ISINSCOPE('Table 2'[Level2]),_LEVEL2,IF(ISINSCOPE('Table 2'[Level1]),_LEVEL1,SUM('Table'[Market Share])))))

Result is as below.

RicoZhou_2-1665042798855.png

 

Best Regards,
Rico Zhou

 

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

 

Helpful resources

Announcements
Fabric Data Days Carousel

Fabric Data Days

Advance your Data & AI career with 50 days of live learning, contests, hands-on challenges, study groups & certifications and more!

October Power BI Update Carousel

Power BI Monthly Update - October 2025

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

FabCon Atlanta 2026 carousel

FabCon Atlanta 2026

Join us at FabCon Atlanta, March 16-20, for the ultimate Fabric, Power BI, AI and SQL community-led event. Save $200 with code FABCOMM.

Top Solution Authors