The ultimate Fabric, Power BI, SQL, and AI community-led learning event. Save €200 with code FABCOMM.
Get registeredEnhance your career with this limited time 50% discount on Fabric and Power BI exams. Ends August 31st. Request your voucher.
Hi there,
I am trying to replicate an existing report visual in PowerBI and I'm not sure how to accomplish it. The matric visual appears to be my best bet but I'm struggling to understand how to
I'm not sure how to explain it so a sample might be the best. The input is very basic and you could presume its originally sourced from a table of transactions which is then aggregated by item sold,repaired, recycled over year end and regions.
In the desired output the % New Market is the value New Market as a percentage of the total across the region.
The matrix visual allows me to add a row total but I'd like to instead include the calculation. I have created measures for the items sold, repaired, recycled and included them on the values section of the matrix visual. Year and Region are dimensions on the rows section.
How do I calculate the formula (measure, calc column, something else) and where do I add it to the visual?
Year End | Region | Items Sold | Items Repaired | Items Recycled |
2020 | New Market | 418 | 352 | 412 |
2020 | Established | 606 | 368 | 141 |
2020 | Home | 641 | 407 | 388 |
2021 | New Market | 146 | 395 | 598 |
2021 | Established | 133 | 359 | 148 |
2021 | Home | 414 | 139 | 507 |
2022 | New Market | 214 | 498 | 270 |
2022 | Established | 316 | 379 | 444 |
2022 | Home | 140 | 648 | 347 |
2023 | New Market | 222 | 136 | 629 |
2023 | Established | 483 | 132 | 373 |
2023 | Home | 168 | 395 | 467 |
2024 | New Market | 347 | 302 | 190 |
2024 | Established | 528 | 433 | 302 |
2024 | Home | 536 | 497 | 224 |
Year End | Region | Items Sold | Items Repaired | Items Recycled |
2020 | New Market | 418 | 352 | 412 |
2020 | Established | 606 | 368 | 141 |
2020 | Home | 641 | 407 | 388 |
% New Market | 25% | 31% | 44% | |
2021 | New Market | 146 | 395 | 598 |
2021 | Established | 133 | 359 | 148 |
2021 | Home | 414 | 139 | 507 |
% New Market | 21% | 44% | 48% | |
2022 | New Market | 214 | 498 | 270 |
2022 | Established | 316 | 379 | 444 |
2022 | Home | 140 | 648 | 347 |
% New Market | 32% | 33% | 25% | |
2023 | New Market | 222 | 136 | 629 |
2023 | Established | 483 | 132 | 373 |
2023 | Home | 168 | 395 | 467 |
% New Market | 25% | 21% | 43% | |
2024 | New Market | 347 | 302 | 190 |
2024 | Established | 528 | 433 | 302 |
2024 | Home | 536 | 497 | 224 |
% New Market | 25% | 25% | 27% |
Solved! Go to Solution.
I was able to get something close to your dsired output:
This is using a matrix visual, three measures for your columns, and an additional measure to capture reusable dynamic formatting string:
Items Recycled_Subtotal% =
VAR _sum = SUM( 'Table'[Items Recycled] )
VAR _sumNewMarketOnly =
CALCULATE(
SUM( 'Table'[Items Recycled] ),
TREATAS( { "New Market" }, 'Table'[Region] )
)
RETURN
IF(
ISFILTERED( 'Table'[Region] ),
_sum,
DIVIDE(
_sumNewMarketOnly,
_sum
)
)
Items Repaired_Subtotal% =
VAR _sum = SUM( 'Table'[Items Repaired] )
VAR _sumNewMarketOnly =
CALCULATE(
SUM( 'Table'[Items Repaired] ),
TREATAS( { "New Market" }, 'Table'[Region] )
)
RETURN
IF(
ISFILTERED( 'Table'[Region] ),
_sum,
DIVIDE(
_sumNewMarketOnly,
_sum
)
)
Items Sold_Subtotal% =
VAR _sum = SUM( 'Table'[Items Sold] )
VAR _sumNewMarketOnly =
CALCULATE(
SUM( 'Table'[Items Sold] ),
TREATAS( { "New Market" }, 'Table'[Region] )
)
RETURN
IF(
ISFILTERED( 'Table'[Region] ),
_sum,
DIVIDE(
_sumNewMarketOnly,
_sum
)
)
Dynamic Format = IF( ISFILTERED( 'Table'[Region] ), "0", "0%" )
For each of the measures (not including [Dynamic Format]), set the format to Dynamic, and put [Dynamic Format] in the Format bar:
Here are the steps to update the matrix visual's formatting to match what I have at the top.
1) Add in Table[Year End] and Table[Region] to Rows and the three measures (Items Recycled_Subtotal%, Items Repaired_Subtotal%, Items Sold_Subtotal%)
2) Rename the measures so they match the columns they are based on
3) Change in Format visual > Visual > Layout and style presets:
4) Change in Format visual > Visual > Blank rows:
5) Change in Format visual > Visual > Row headers:
6) Change Format visual > Visual > Row subtotals > Per row level: On
6a) For Row level: Region
6b) For Row level: Year End
I may not be understanding your question, let me know if the below answer isn't responsive.
To clarify, as noted in my #1 step, you need to create all three measures I define and add them to the matrix visual: [Items Recycled_Subtotal%], [Items Repaired_Subtotal%], and [Items Sold_Subtotal%]. I had sort of lazily put all the measures in one code block, so this point may have been a bit muddled. I just edited my response to clearly deliniate the three calculation measures + measure for dynamic formatting.
The three measures and the dynamic format all toggle on the same thing, namely whether we are in a filter context where 'Table'[Region] is getting filtered (in retrospect, probably ISINSCOPE is the better test in case you have outside filters on Region). There are three levels in the matrix we defined: All (grand total, which we hide) > Year End > Region.
To show more specifically, here is the breakdown of 'is or is not filtered' context in the visual:
If you want to get a better sense of how the measures are working, here are the components split out on Items Sold (they all follow same pattern, so just looking at one should be sufficient).
Sum Regular = SUM( 'Table'[Items Sold] )
Sum New Market Only =
CALCULATE(
SUM( 'Table'[Items Sold] ),
TREATAS( { "New Market" }, 'Table'[Region] )
)
As we can see, the regular SUM is both:
And, the New Market sum always just gives us the SUM for Region = 'New Market' for the given Year End. We only need to use it at the Year End level as our numerator.
On your last question re: how is % New Market working, this is just some formatting trickery - the relevant steps are:
Note: in my instructions, we are actually turning on the 'Per row level' toggle to change these settings per level, mainly to turn off subtotals at Year End level and change the subtotal label at Region level. The general concept applies the same, though.
I was able to get something close to your dsired output:
This is using a matrix visual, three measures for your columns, and an additional measure to capture reusable dynamic formatting string:
Items Recycled_Subtotal% =
VAR _sum = SUM( 'Table'[Items Recycled] )
VAR _sumNewMarketOnly =
CALCULATE(
SUM( 'Table'[Items Recycled] ),
TREATAS( { "New Market" }, 'Table'[Region] )
)
RETURN
IF(
ISFILTERED( 'Table'[Region] ),
_sum,
DIVIDE(
_sumNewMarketOnly,
_sum
)
)
Items Repaired_Subtotal% =
VAR _sum = SUM( 'Table'[Items Repaired] )
VAR _sumNewMarketOnly =
CALCULATE(
SUM( 'Table'[Items Repaired] ),
TREATAS( { "New Market" }, 'Table'[Region] )
)
RETURN
IF(
ISFILTERED( 'Table'[Region] ),
_sum,
DIVIDE(
_sumNewMarketOnly,
_sum
)
)
Items Sold_Subtotal% =
VAR _sum = SUM( 'Table'[Items Sold] )
VAR _sumNewMarketOnly =
CALCULATE(
SUM( 'Table'[Items Sold] ),
TREATAS( { "New Market" }, 'Table'[Region] )
)
RETURN
IF(
ISFILTERED( 'Table'[Region] ),
_sum,
DIVIDE(
_sumNewMarketOnly,
_sum
)
)
Dynamic Format = IF( ISFILTERED( 'Table'[Region] ), "0", "0%" )
For each of the measures (not including [Dynamic Format]), set the format to Dynamic, and put [Dynamic Format] in the Format bar:
Here are the steps to update the matrix visual's formatting to match what I have at the top.
1) Add in Table[Year End] and Table[Region] to Rows and the three measures (Items Recycled_Subtotal%, Items Repaired_Subtotal%, Items Sold_Subtotal%)
2) Rename the measures so they match the columns they are based on
3) Change in Format visual > Visual > Layout and style presets:
4) Change in Format visual > Visual > Blank rows:
5) Change in Format visual > Visual > Row headers:
6) Change Format visual > Visual > Row subtotals > Per row level: On
6a) For Row level: Region
6b) For Row level: Year End
Hi @MarkLaf
Thanks for your detailed and very helpful response.
I hope I understand your solution correctly. You use the dynamic format to toggle whether a measures output is displayed as a precentage of total or the sum of the particular item.
I presume the measure's DAX is repeated for ease of writing and its not important that the "other measures" percentages are calculated because they won't get toggled ?
What I'm not clear on is how the % New Market measure is activated/toggled as a percentage or how it materialises on the table?Wouldn't you need to include the measure %New Market twice in the values list or is the tabular layout an important component of the solution?
I may not be understanding your question, let me know if the below answer isn't responsive.
To clarify, as noted in my #1 step, you need to create all three measures I define and add them to the matrix visual: [Items Recycled_Subtotal%], [Items Repaired_Subtotal%], and [Items Sold_Subtotal%]. I had sort of lazily put all the measures in one code block, so this point may have been a bit muddled. I just edited my response to clearly deliniate the three calculation measures + measure for dynamic formatting.
The three measures and the dynamic format all toggle on the same thing, namely whether we are in a filter context where 'Table'[Region] is getting filtered (in retrospect, probably ISINSCOPE is the better test in case you have outside filters on Region). There are three levels in the matrix we defined: All (grand total, which we hide) > Year End > Region.
To show more specifically, here is the breakdown of 'is or is not filtered' context in the visual:
If you want to get a better sense of how the measures are working, here are the components split out on Items Sold (they all follow same pattern, so just looking at one should be sufficient).
Sum Regular = SUM( 'Table'[Items Sold] )
Sum New Market Only =
CALCULATE(
SUM( 'Table'[Items Sold] ),
TREATAS( { "New Market" }, 'Table'[Region] )
)
As we can see, the regular SUM is both:
And, the New Market sum always just gives us the SUM for Region = 'New Market' for the given Year End. We only need to use it at the Year End level as our numerator.
On your last question re: how is % New Market working, this is just some formatting trickery - the relevant steps are:
Note: in my instructions, we are actually turning on the 'Per row level' toggle to change these settings per level, mainly to turn off subtotals at Year End level and change the subtotal label at Region level. The general concept applies the same, though.
Hi @mobul,
Thank you for reaching out to Microsoft Fabric Community.
Thank you @MarkLaf and @Irwan for the prompt response.
As we haven’t heard back from you, we wanted to kindly follow up to check if the solution provided by the super user resolved your issue.
If our super user response resolved your issue, please mark it as "Accept as solution" and click "Yes" if you found it helpful.
Thanks and regards,
Anjan Kumar Chippa
Hi @mobul,
We wanted to kindly follow up to check if the solution provided by the super user resolved your issue.
If our super user response resolved your issue, please mark it as "Accept as solution" and click "Yes" if you found it helpful.
Thanks and regards,
Anjan Kumar Chippa
Hi @mobul,
As we haven’t heard back from you, we wanted to kindly follow up to check if the solution provided by the super user resolved your issue.
If our super user response resolved your issue, please mark it as "Accept as solution" and click "Yes" if you found it helpful.
Thanks and regards,
Anjan Kumar Chippa
hello @mobul
please check if this accomodate your need.
1. unpivot your table (since you want to measure % New Market for all Recycled, Repaired, and Sold)
2. since you want to insert measure in row matrix, you need create 4 measures with following DAX
New Market =
CALCULATE(
MAX('Table'[Value]),
'Table'[Region]="New Market"
)
Home =
CALCULATE(
MAX('Table'[Value]),
'Table'[Region]="Home"
)
Established =
CALCULATE(
MAX('Table'[Value]),
'Table'[Region]="Established"
)
% New Market =
var _New =
CALCULATE(
MAX('Table'[Value]),
'Table'[Region]="New Market"
)
var _Total =
SUM('Table'[Value])
Return
DIVIDE(
_New,
_Total
)
4. assign those 4 measures as Matrix Values, Year as Matrix Row, and Attribute as Matrix Column (attribute is consisted of Recyled, Repaired, and Sold).
Hope this will help.
Thank you.