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
Hi all,
Here is a Christmas brain cracker for our DAX specialists!
I want to create a DAX measure that calculates the percentage of values per category in a table to the total of that table, with the following custom rounding:
- All percentages need to be rounded down to the nearest integer.
- Then it needs to be identified how much percentage points are missing to reach the 100% in total.
- Next, these percentage points need to be added each to the percentages with the largest decimal part in descending order.
Please note the dataset is huge so the impact of the DAX calculation should be limited as much as possible
So for example:
Category A: 26.98%,
Category B: 34.78%,
Category C: 38.24%
Rounded down this becomes:
Category A: 26
Category B: 34
Category C: 38
26 + 34 + 38 = 98 -> 2 missing percentage points
These missing percentage points need to be assigned to the 2 percentages with the highest decimal part:
Category A: 27
Category B: 35
Category C: 38
27 + 35 + 38 = 100%
How can I do this with DAX? I think some iteration and /or buffering is required, but how do I do this?
@parry2k maybe you know?
Solved! Go to Solution.
@PunchBird I have modified things to be more in line with your data and requirements. See if this works. Updated PBIX is attached below signature.
Measure 2 =
VAR __Cat2 = MAX('Table'[Category2])
VAR __Table =
GENERATE(
SUMMARIZE(
FILTER(ALLSELECTED('Table'), [Category2] = __Cat2),
'Table'[Category1],'Table'[Category2],"Value",MAX([Percentage])),
VAR __Value = [Value]
VAR __RD = ROUNDDOWN(__Value,0)
VAR __Decimal = __Value - __RD
RETURN
ROW(
"RD", __RD,
"Decimal", __Decimal
)
)
VAR __MaxDecimal = MAXX(__Table,[Decimal])
VAR __MaxCategory = MAXX(FILTER(__Table, [Decimal] = __MaxDecimal),[Category1])
VAR __2ndMaxDecimal = MAXX(FILTER(__Table, [Category1] <> __MaxCategory), [Decimal])
VAR __2ndMaxCategory = MAXX(FILTER(__Table, [Category1] <> __MaxCategory && [Decimal] = __2ndMaxDecimal),[Category1])
VAR __Category = MAX('Table'[Category1])
VAR __Result =
IF(
__Category = __MaxCategory || __Category = __2ndMaxCategory,
ROUNDUP(MAX([Percentage]),0),
ROUNDDOWN(MAX([Percentage]),0)
)
RETURN
__Result //CONCATENATEX(__Table, [Category1]&":"&[Category2]&":"&[Value]&":"&[RD]&":"&[Decimal],UNICHAR(10)&UNICHAR(13))
@PunchBird Easy fix for that, see below and attached PBIX.
Measure 2 =
VAR __Cat2 = MAX('Table'[Category2])
VAR __Table =
GENERATE(
SUMMARIZE(
FILTER(ALLSELECTED('Table'), [Category2] = __Cat2),
'Table'[Category1],'Table'[Category2],"Value",MAX([Percentage])),
VAR __Value = [Value]
VAR __RD = ROUNDDOWN(__Value,0)
VAR __Decimal = __Value - __RD
RETURN
ROW(
"RD", __RD,
"Decimal", __Decimal
)
)
VAR __MaxDecimal = MAXX(__Table,[Decimal])
VAR __MaxCategory = MAXX(FILTER(__Table, [Decimal] = __MaxDecimal),[Category1])
VAR __2ndMaxDecimal = MAXX(FILTER(__Table, [Category1] <> __MaxCategory), [Decimal])
VAR __2ndMaxCategory = MAXX(FILTER(__Table, [Category1] <> __MaxCategory && [Decimal] = __2ndMaxDecimal),[Category1])
VAR __Category = MAX('Table'[Category1])
VAR __SumDown = SUMX(__Table, [RD])
VAR __Result =
SWITCH(__SumDown,
99,
IF(
__Category = __MaxCategory,
ROUNDUP(MAX([Percentage]),0),
ROUNDDOWN(MAX([Percentage]),0)
),
98,
IF(
__Category = __MaxCategory || __Category = __2ndMaxCategory,
ROUNDUP(MAX([Percentage]),0),
ROUNDDOWN(MAX([Percentage]),0)
)
)
RETURN
__Result //CONCATENATEX(__Table, [Category1]&":"&[Category2]&":"&[Value]&":"&[RD]&":"&[Decimal],UNICHAR(10)&UNICHAR(13))
Great, that worked! Thanks so much, very much appreciated 🙂
And I added an alternative for SWITCH in case nothing needs to be rounded (in the unlikely case all are numbers with 0 decimals)
@PunchBird alright here it is, let me know if you have any questions. I might end up doing a video on it and will explain everything, not sure yet though.
Subscribe to the @PowerBIHowTo YT channel for an upcoming video on List and Record functions in Power Query!!
Learn Power BI and Fabric - subscribe to our YT channel - Click here: @PowerBIHowTo
If my solution proved useful, I'd be delighted to receive Kudos. When you put effort into asking a question, it's equally thoughtful to acknowledge and give Kudos to the individual who helped you solve the problem. It's a small gesture that shows appreciation and encouragement! ❤
Did I answer your question? Mark my post as a solution. Proud to be a Super User! Appreciate your Kudos 🙂
Feel free to email me with any of your BI needs.
hi @PunchBird Sorry, I was traveling and was not able to get to you on the pbix file. Let me know if you still need the file. Cheers!!
Subscribe to the @PowerBIHowTo YT channel for an upcoming video on List and Record functions in Power Query!!
Learn Power BI and Fabric - subscribe to our YT channel - Click here: @PowerBIHowTo
If my solution proved useful, I'd be delighted to receive Kudos. When you put effort into asking a question, it's equally thoughtful to acknowledge and give Kudos to the individual who helped you solve the problem. It's a small gesture that shows appreciation and encouragement! ❤
Did I answer your question? Mark my post as a solution. Proud to be a Super User! Appreciate your Kudos 🙂
Feel free to email me with any of your BI needs.
@PunchBird collapsed version:
2 - Final Share Short % =
//select current visible category group
VAR __currentCategory2 = SELECTEDVALUE ( Category[Category2] )
//create base table for the current visible category group
VAR __baseTable=
ADDCOLUMNS (
ADDCOLUMNS (
SUMMARIZE (
FILTER (
ALL ( Category ),
Category[Category2] = __currentCategory2
),
Category[Category2],
Category[Category1]
),
"@BaseShare", [1 - Base Share %], --change this measure to the % measure
"@RoundShare", ROUNDDOWN ( [1 - Base Share %], 2 )
),
"@RemainderShare", [@BaseShare] - [@RoundShare]
)
//get the count of remainder to be distributed
VAR __distributionCount = INT ( SUMX ( __baseTable, [@RemainderShare] * 100 ) )
//find out to which categories the remainder will be distributed, in other words, what base % will be rounded upwards
VAR __distributionTable =
SELECTCOLUMNS (
WINDOW (
1, ABS,
__distributionCount, ABS,
__baseTable,
ORDERBY ( [@RemainderShare], DESC )
),
[Category1],
[Category2]
)
//round up the share %
VAR __roundUp =
CALCULATE (
ROUNDUP ( [Sum Value], 0 ),
KEEPFILTERS (
TREATAS ( __distributionTable, Category[Category1], Category[Category2] )
)
)
//find result, the one which are not rounded up will be rounded down
RETURN COALESCE ( __roundUp, ROUNDDOWN ( [Sum Value], 0 ) )
Subscribe to the @PowerBIHowTo YT channel for an upcoming video on List and Record functions in Power Query!!
Learn Power BI and Fabric - subscribe to our YT channel - Click here: @PowerBIHowTo
If my solution proved useful, I'd be delighted to receive Kudos. When you put effort into asking a question, it's equally thoughtful to acknowledge and give Kudos to the individual who helped you solve the problem. It's a small gesture that shows appreciation and encouragement! ❤
Did I answer your question? Mark my post as a solution. Proud to be a Super User! Appreciate your Kudos 🙂
Feel free to email me with any of your BI needs.
@parry2k I am trying to reproduce this but I am getting a bit lost... are you able to share the PBIX-file to which this measure belongs? Many thanks!
Wow, that looks really amazing. I need to watch your videos about the WINDOW function to understand what you've done, that's going to be my next task on my list. Thanks a lot ! 🙂
@PunchBird you already have an excellent solution from @Greg_Deckler I wanted to try new WINDOW functions and see if that will help. Keep in mind, it is based on that you have a category dimension table that has a relationship with the transaction table.
here is the DAX measure, some of the steps can be collapsed into one step but I just added multiple variables for clarity and to explain the logic behind the solution. ( I will post a collapsed version soon)
2 - Final Share % =
//select current visible category group
VAR __currentCategory2 = SELECTEDVALUE ( Category[Category2] )
//create base table for the current visible category group
VAR __baseTable=
ADDCOLUMNS (
SUMMARIZE (
FILTER (
ALL ( Category ),
Category[Category2] = __currentCategory2
),
Category[Category2],
Category[Category1]
),
"@BaseShare", [1 - Base Share %] --change this measure to the % measure
)
//add a column to round down base %
VAR __roundTable =
ADDCOLUMNS (
__baseTable,
"@RoundShare", ROUNDDOWN ( [@BaseShare], 2 )
)
//add a column to difference between base share and round down share %
VAR __remainderTable =
ADDCOLUMNS (
__roundTable,
"@RemainderShare", [@BaseShare] - [@RoundShare]
)
//get the count of remainder to be distributed
VAR __distributionCount = INT ( SUMX ( __remainderTable, [@RemainderShare] * 100 ) )
//find out to which categories the remainder will be distributed, in other words, what base % will be rounded upwards
VAR __distributionTable =
SELECTCOLUMNS (
WINDOW (
1, ABS,
__distributionCount, ABS,
__remainderTable,
ORDERBY ( [@RemainderShare], DESC )
),
[Category1],
[Category2]
)
//round up the share %
VAR __roundUp =
CALCULATE (
ROUNDUP ( [Sum Value], 0 ),
KEEPFILTERS (
TREATAS ( __distributionTable, Category[Category1], Category[Category2] )
)
)
//find result, the one which are not rounded up will be rounded down
RETURN IF ( __roundUp == BLANK (), ROUNDDOWN ( [Sum Value], 0 ), __roundUp )
Also, if interested check out the full playlist on my youtube channel for new WINDOW DAX functions. https://youtube.com/playlist?list=PLiYSIjh4cEx0BDzmo48YIPzw_dIC0Kd95
Subscribe to the @PowerBIHowTo YT channel for an upcoming video on List and Record functions in Power Query!!
Learn Power BI and Fabric - subscribe to our YT channel - Click here: @PowerBIHowTo
If my solution proved useful, I'd be delighted to receive Kudos. When you put effort into asking a question, it's equally thoughtful to acknowledge and give Kudos to the individual who helped you solve the problem. It's a small gesture that shows appreciation and encouragement! ❤
Did I answer your question? Mark my post as a solution. Proud to be a Super User! Appreciate your Kudos 🙂
Feel free to email me with any of your BI needs.
@Greg_Deckler @ppm1 @parry2k thanks for your calculations and input! However, I just realized I do'nt have one but two categories, which each can be filtered separately. The percentages of Category2 make up a total of 100%
So my table looks something like this:
Category1 | Category2 | Percentage |
A | X | 43.75 |
B | X | 12.50 |
C | X | 12.50 |
D | X | 31.25 |
A | Y | 40.38 |
B | Y | 5.77 |
C | Y | 23.08 |
D | Y | 30.77 |
Each Category2 rounded down this becomes:
Category1 | Category2 | Percentage |
A | X | 43 |
B | X | 12 |
C | X | 12 |
D | X | 31 |
A | Y | 40 |
B | Y | 5 |
C | Y | 23 |
D | Y | 30 |
Category2 X -> 2 missing percentage points
Category2 Y -> 2 missing percentage points
These missing percentage points need to be assigned to the 2 percentages with the highest decimal part. Please note there is a tie in X of Category2 so one percentage point goes to the first. I guess it must be fairly simple to add to the calculations you provided, but I can't manage to get it work... any ideas? Many thanks in advance!
Category1 | Category2 | Rounded percentage |
A | X | 44 |
B | X | 13 |
C | X | 12 |
D | X | 31 |
A | Y | 40 |
B | Y | 6 |
C | Y | 23 |
D | Y | 31 |
@PunchBird I have modified things to be more in line with your data and requirements. See if this works. Updated PBIX is attached below signature.
Measure 2 =
VAR __Cat2 = MAX('Table'[Category2])
VAR __Table =
GENERATE(
SUMMARIZE(
FILTER(ALLSELECTED('Table'), [Category2] = __Cat2),
'Table'[Category1],'Table'[Category2],"Value",MAX([Percentage])),
VAR __Value = [Value]
VAR __RD = ROUNDDOWN(__Value,0)
VAR __Decimal = __Value - __RD
RETURN
ROW(
"RD", __RD,
"Decimal", __Decimal
)
)
VAR __MaxDecimal = MAXX(__Table,[Decimal])
VAR __MaxCategory = MAXX(FILTER(__Table, [Decimal] = __MaxDecimal),[Category1])
VAR __2ndMaxDecimal = MAXX(FILTER(__Table, [Category1] <> __MaxCategory), [Decimal])
VAR __2ndMaxCategory = MAXX(FILTER(__Table, [Category1] <> __MaxCategory && [Decimal] = __2ndMaxDecimal),[Category1])
VAR __Category = MAX('Table'[Category1])
VAR __Result =
IF(
__Category = __MaxCategory || __Category = __2ndMaxCategory,
ROUNDUP(MAX([Percentage]),0),
ROUNDDOWN(MAX([Percentage]),0)
)
RETURN
__Result //CONCATENATEX(__Table, [Category1]&":"&[Category2]&":"&[Value]&":"&[RD]&":"&[Decimal],UNICHAR(10)&UNICHAR(13))
Brilliant, it works, also in my 'real' dataset! Thanks a lot @Greg_Deckler , you're a star! 🙂
And also thanks to all other contributors @bolfri @ppm1 @parry2k , you helped me shape my thoughts.
@Greg_Deckler oops I noticed an error - it looks like the result now always rounds up two values, even if only rounding up one value should have been done, see example below for category Z... which should have been 50 + 24 + 16 + 10. Any thoughts on this?
@PunchBird Easy fix for that, see below and attached PBIX.
Measure 2 =
VAR __Cat2 = MAX('Table'[Category2])
VAR __Table =
GENERATE(
SUMMARIZE(
FILTER(ALLSELECTED('Table'), [Category2] = __Cat2),
'Table'[Category1],'Table'[Category2],"Value",MAX([Percentage])),
VAR __Value = [Value]
VAR __RD = ROUNDDOWN(__Value,0)
VAR __Decimal = __Value - __RD
RETURN
ROW(
"RD", __RD,
"Decimal", __Decimal
)
)
VAR __MaxDecimal = MAXX(__Table,[Decimal])
VAR __MaxCategory = MAXX(FILTER(__Table, [Decimal] = __MaxDecimal),[Category1])
VAR __2ndMaxDecimal = MAXX(FILTER(__Table, [Category1] <> __MaxCategory), [Decimal])
VAR __2ndMaxCategory = MAXX(FILTER(__Table, [Category1] <> __MaxCategory && [Decimal] = __2ndMaxDecimal),[Category1])
VAR __Category = MAX('Table'[Category1])
VAR __SumDown = SUMX(__Table, [RD])
VAR __Result =
SWITCH(__SumDown,
99,
IF(
__Category = __MaxCategory,
ROUNDUP(MAX([Percentage]),0),
ROUNDDOWN(MAX([Percentage]),0)
),
98,
IF(
__Category = __MaxCategory || __Category = __2ndMaxCategory,
ROUNDUP(MAX([Percentage]),0),
ROUNDDOWN(MAX([Percentage]),0)
)
)
RETURN
__Result //CONCATENATEX(__Table, [Category1]&":"&[Category2]&":"&[Value]&":"&[RD]&":"&[Decimal],UNICHAR(10)&UNICHAR(13))
Great, that worked! Thanks so much, very much appreciated 🙂
And I added an alternative for SWITCH in case nothing needs to be rounded (in the unlikely case all are numbers with 0 decimals)
Hi,
I think you're trying to do it wrong. Do not create a too complex measures that's not nessesery. 😄
In Power Query M:
Add a Percentage_to_number column which is your oryginal Percentage divided by 100 and make this as a number (with decimal places)
let
Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WclTSUYoAYhNjPXNTpVidaCUnqIihkZ6pAVjEGUPEBSpibKhnBNEFMicSZI6BnrEF3ByQiKmeuTncGJCAkbGegQXcGJCIsQFYTSwA", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [Category1 = _t, Category2 = _t, Percentage = _t]),
#"Replaced Value" = Table.ReplaceValue(Source,".",",",Replacer.ReplaceText,{"Percentage"}),
#"Changed Type" = Table.TransformColumnTypes(#"Replaced Value",{{"Category1", type text}, {"Category2", type text}, {"Percentage", type number}}),
#"Added Custom" = Table.AddColumn(#"Changed Type", "Percentage_to_number", each [Percentage] / 100),
#"Changed Type1" = Table.TransformColumnTypes(#"Added Custom",{{"Percentage_to_number", type number}})
in
#"Changed Type1"
In DAX:
Create a Percentage mesure and change the format to Percentage:
Percentage measure = SUM('Sample'[Percentage_to_number])
As you can see it's almost the same as previous.
To get rid of decimal places simply change it to 0.
Final efect:
The numbers are correct and they are calculated by mathematic law 🙂
Proud to be a Super User!
Many thanks! This would have been a great solution... but look at the results of the Percentage measure of Category X... 44 + 13 + 13 + 31 = 101 !
The tie (and I think any two values with ,5 decimal in one category) seems to mess up the total... hence the need for custom rounding. Let me know your thoughts on how to resolve this, thanks 🙂
I see your point. You said that you want rounding down, so...
On your oryginal data add a new DAX column:
Result in table:
As you can see the missing 2% were divided between Category A and D.
But we can use RoundingUp to give this missing 2% to category B and C.
Again. Add a new Column:
RoundingUp = ROUNDUP([Percentage],0)
And another new column:
New Percentage UP =
var numerator= [RoundingUp]
var denominator= CALCULATE(SUM('Sample'[RoundingUp]),ALLEXCEPT('Sample','Sample'[Category2]))
return DIVIDE(numerator,denominator)
Result in table:
Based on the path you'll choose you will get different results.
Choose the one you prefer.
Proud to be a Super User!
@bolfri thanks for your suggestions, but I would like to avoid adding extra columns, because this will increase the model size and impact performance dramatically (the fact table has more than a million rows). In addition, the requirement is that the remaining percent points have to be added to the values with the largest decimal, in descending order (see my explanation above)...
You you want to change the value? If the Category 2 and 3 have same value, why do you want to give them differete percentage impact? 😄 You can do it in one step or by a measure. It was just an example of the results. If you can accept that (eg. this round up solution), I can give you Power Query M steps to change it in the source.
Proud to be a Super User!
@bolfriyour comment makes sense, but unfortunately I am not allowed to deviate from the requirements re. the distribution of the percent points. I am definitely curious to see what a Power Query M step for this would look like 🙂
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 |
---|---|
94 | |
86 | |
82 | |
70 | |
49 |
User | Count |
---|---|
143 | |
123 | |
107 | |
61 | |
55 |