Join us at FabCon Atlanta from March 16 - 20, 2026, for the ultimate Fabric, Power BI, AI and SQL community-led event. Save $200 with code FABCOMM.
Register now!The Power BI Data Visualization World Championships is back! Get ahead of the game and start preparing now! Learn more
Hi, using the table below, how can I get the highest Reason_Ended by month shown in the lower table, please?
| End_Date | Customer | Reason_Ended |
| 01/04/2024 | 1 | Too Expensive |
| 01/04/2024 | 2 | Too Expensive |
| 01/04/2024 | 3 | Hard To Use |
| 01/04/2024 | 4 | Too Expensive |
| 01/05/2024 | 5 | I'll Be Back |
| 01/05/2024 | 6 | I'll Be Back |
| 01/05/2024 | 7 | Too Expensive |
| 01/05/2024 | 8 | Hard To Use |
| 01/05/2024 | 9 | I'll Be Back |
| 01/06/2024 | 10 | Hard To Use |
| 01/06/2024 | 11 | Too Expensive |
| 01/06/2024 | 12 | Hard To Use |
| 01/06/2024 | 13 | Hard To Use |
| 01/07/2024 | 14 | Too Expensive |
| 01/07/2024 | 15 | Too Expensive |
| 01/07/2024 | 16 | I'll Be Back |
| 01/07/2024 | 17 | I'll Be Back |
| 01/07/2024 | 18 | Too Expensive |
| 01/07/2024 | 19 | Too Expensive |
| Month | Highest_Reason_Ended |
| April | Too Expensive |
| May | I'll Be Back |
| June | Hard To Use |
| July | Too Expensive |
Thanks
Solved! Go to Solution.
Hi @RichOB ,
Thank you for reaching out to Microsoft Fabric Community.
Thank you @johnt75 and @bhanu_gautam for the prompt response.
first group the data by End_Date and Reason_Ended and get the count of rows and then apply rank for the result based on count for each month. once we got the count filter the data which is having the rank as 1. This will give your expected result. I have used power query to do this. Also attached pbix file for reference.
let
Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WMjDUNTDRNTIwMlHSUTIE4pD8fAXXioLUvOLMslSlWB00JUaElRgDsUdiUYpCSL5CaDEWBSY4zTCFKTEFYs+YUgMDI/OcHAWnVAWnxOTsQwswFZoRq9CcsKUWOBwOV2BJwDIzeEAa4DAKoQJ3WCPUGBE0BVdYm8NV4A5shBpTItQQCmiESnOiVVoQYa8lpppYAA==", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [End_Date = _t, Customer = _t, Reason_Ended = _t]),
#"Changed Type" = Table.TransformColumnTypes(Source,{{"End_Date", type date}, {"Customer", Int64.Type}, {"Reason_Ended", type text}}),
// Group by End_Date and Reason_Ended, counting rows
#"Grouped Rows" = Table.Group(#"Changed Type", {"End_Date", "Reason_Ended"}, {{"Count", each Table.RowCount(_), Int64.Type}}),
// Sort by End_Date ascending and Count descending (highest count first)
#"Sorted" = Table.Sort(#"Grouped Rows", {{"End_Date", Order.Ascending}, {"Count", Order.Descending}}),
// Group by End_Date to get nested tables of reasons per month
GroupedByMonth = Table.Group(#"Sorted", {"End_Date"}, {{"AllData", each _, type table [End_Date=nullable date, Reason_Ended=nullable text, Count=Int64.Type]}}),
// Add Rank (index starting at 1) in each grouped subtable
AddRankPerGroup = Table.TransformColumns(
GroupedByMonth,
{"AllData", each Table.AddIndexColumn(_, "Rank", 1, 1, Int64.Type)}
),
// Expand the grouped tables back into a flat table
Expanded = Table.ExpandTableColumn(AddRankPerGroup, "AllData", {"Reason_Ended", "Count", "Rank"})
in
Expanded
PFBS for expected results:
If this post helps, then please consider Accepting as solution to help the other members find it more quickly, don't forget to give a "Kudos" – I’d truly appreciate it!
Thank you!!
Hi @RichOB ,
I hope the information provided is helpful. Feel free to reach out if you have any further questions or would like to discuss this in more detail. If responses provided answers your question, please accept it as a solution so other community members with similar problems can find a solution faster.
Thank you!!
Hi @RichOB ,
I wanted to check if you had the opportunity to review the information provided. Please feel free to contact us if you have any further questions. If the responses has addressed your query, please accept it as a solution and give a 'Kudos' so other members can easily find it.
Thank you!!
Hi @RichOB ,
May I ask if the provided solution helped in resolving the issue? If so, please mark the helpful reply and accept it as the solution. This will be helpful for other community members who have similar problems to solve it faster.
Thank you!!
Hi @RichOB ,
Thank you for reaching out to Microsoft Fabric Community.
Thank you @johnt75 and @bhanu_gautam for the prompt response.
first group the data by End_Date and Reason_Ended and get the count of rows and then apply rank for the result based on count for each month. once we got the count filter the data which is having the rank as 1. This will give your expected result. I have used power query to do this. Also attached pbix file for reference.
let
Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WMjDUNTDRNTIwMlHSUTIE4pD8fAXXioLUvOLMslSlWB00JUaElRgDsUdiUYpCSL5CaDEWBSY4zTCFKTEFYs+YUgMDI/OcHAWnVAWnxOTsQwswFZoRq9CcsKUWOBwOV2BJwDIzeEAa4DAKoQJ3WCPUGBE0BVdYm8NV4A5shBpTItQQCmiESnOiVVoQYa8lpppYAA==", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [End_Date = _t, Customer = _t, Reason_Ended = _t]),
#"Changed Type" = Table.TransformColumnTypes(Source,{{"End_Date", type date}, {"Customer", Int64.Type}, {"Reason_Ended", type text}}),
// Group by End_Date and Reason_Ended, counting rows
#"Grouped Rows" = Table.Group(#"Changed Type", {"End_Date", "Reason_Ended"}, {{"Count", each Table.RowCount(_), Int64.Type}}),
// Sort by End_Date ascending and Count descending (highest count first)
#"Sorted" = Table.Sort(#"Grouped Rows", {{"End_Date", Order.Ascending}, {"Count", Order.Descending}}),
// Group by End_Date to get nested tables of reasons per month
GroupedByMonth = Table.Group(#"Sorted", {"End_Date"}, {{"AllData", each _, type table [End_Date=nullable date, Reason_Ended=nullable text, Count=Int64.Type]}}),
// Add Rank (index starting at 1) in each grouped subtable
AddRankPerGroup = Table.TransformColumns(
GroupedByMonth,
{"AllData", each Table.AddIndexColumn(_, "Rank", 1, 1, Int64.Type)}
),
// Expand the grouped tables back into a flat table
Expanded = Table.ExpandTableColumn(AddRankPerGroup, "AllData", {"Reason_Ended", "Count", "Rank"})
in
Expanded
PFBS for expected results:
If this post helps, then please consider Accepting as solution to help the other members find it more quickly, don't forget to give a "Kudos" – I’d truly appreciate it!
Thank you!!
If you're looking for the most frequent reason you can use
Most frequent reason =
VAR SummaryTable =
ADDCOLUMNS (
SUMMARIZE ( 'Table', 'Date'[Year month], 'Table'[Reason_Ended] ),
"@num", CALCULATE ( COUNTROWS ( 'Table' ) )
)
VAR Result =
SELECTCOLUMNS (
TOPN ( 1, SummaryTable, [@num], DESC ),
"@reason", 'Table'[Reason_Ended]
)
RETURN
Result
Create a new column to extract the month from the End_Date column. You can do this by using the following Month = FORMAT([End_Date], "MMMM")
Create a new table to count the occurrences of each Reason_Ended by month. You can use the following DAX formula to create this table:
ReasonCount =
SUMMARIZE(
'YourTable',
'YourTable'[Month],
'YourTable'[Reason_Ended],
"Count", COUNT('YourTable'[Reason_Ended])
)
Create a new table to find the highest Reason_Ended by month.
HighestReasonByMonth =
ADDCOLUMNS(
SUMMARIZE(
'ReasonCount',
'ReasonCount'[Month],
"MaxCount", MAX('ReasonCount'[Count])
),
"Highest_Reason_Ended",
CALCULATE(
MAX('ReasonCount'[Reason_Ended]),
FILTER(
'ReasonCount',
'ReasonCount'[Month] = EARLIER('ReasonCount'[Month]) &&
'ReasonCount'[Count] = EARLIER([MaxCount])
)
)
)
Visualize the results by creating a table visual in Power BI and adding the Month and Highest_Reason_Ended columns from the HighestReasonByMonth table.
Proud to be a Super User! |
|
The Power BI Data Visualization World Championships is back! Get ahead of the game and start preparing now!
| User | Count |
|---|---|
| 40 | |
| 38 | |
| 36 | |
| 29 | |
| 28 |
| User | Count |
|---|---|
| 127 | |
| 88 | |
| 78 | |
| 66 | |
| 65 |