Starting December 3, join live sessions with database experts and the Microsoft product team to learn just how easy it is to get started
Learn moreGet certified in Microsoft Fabric—for free! For a limited time, get a free DP-600 exam voucher to use by the end of 2024. Register now
I have the following data fou our use case:
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
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!
Solved! Go to Solution.
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.
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.
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.
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.
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.
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.
Starting December 3, join live sessions with database experts and the Fabric product team to learn just how easy it is to get started.
March 31 - April 2, 2025, in Las Vegas, Nevada. Use code MSCUST for a $150 discount! Early Bird pricing ends December 9th.
User | Count |
---|---|
93 | |
88 | |
84 | |
70 | |
49 |
User | Count |
---|---|
141 | |
120 | |
112 | |
59 | |
59 |