Power BI is turning 10! Tune in for a special live episode on July 24 with behind-the-scenes stories, product evolution highlights, and a sneak peek at what’s in store for the future.
Save the dateEnhance your career with this limited time 50% discount on Fabric and Power BI exams. Ends August 31st. Request your voucher.
Got a dilema ..... in following some directions for sorting a Trade column, i ran into an error due to duplicates. So i followed some instructions of adding a Index column (because the Trade column automatically puts things in alphabetical order), but i got an error and it is related to 2 sets of duplicates. Im not sure how to handle it. Again my goal is i want to be able to sort by column (index) which is the order of items that i want to show in my report vs alphabetical.
im not sure what to do here. How can i sortbycolumn if i getting error related to this duplicates????? i dont want to remove the second set as it is a subset (spaced in some.....). Can PBI even handle subsets like this??
Solved! Go to Solution.
Hi @Anonymous
If the duplicates are subsets of the trade above them, you need to combine their father trade with them to make it clear which father trade they belong to. And this will create unique values for them. Use this new column in your report to display.
Transformation steps are as below.
let
Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WcsssSi3ISUxOLVaK1YlWCsgpzU3KzEvX9U4sKi5JzQMLKgBBUH5peoaupx9cIKQoMze/tATM9whzdNYNT83JTi0C811zUpNLijKTE3N0nYoS8zISc4kwJxYA", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [Trade = _t]),
#"Changed Type" = Table.TransformColumnTypes(Source,{{"Trade", type text}}),
#"Duplicated Column" = Table.DuplicateColumn(#"Changed Type", "Trade", "Trade - Copy"),
#"Split Column by Delimiter" = Table.SplitColumn(#"Duplicated Column", "Trade - Copy", Splitter.SplitTextByEachDelimiter({" "}, QuoteStyle.Csv, false), {"Trade - Copy.1", "Trade - Copy.2"}),
#"Replaced Value" = Table.ReplaceValue(#"Split Column by Delimiter","",null,Replacer.ReplaceValue,{"Trade - Copy.1"}),
#"Filled Down" = Table.FillDown(#"Replaced Value",{"Trade - Copy.1"}),
#"Added Custom" = Table.AddColumn(#"Filled Down", "Custom", each if [#"Trade - Copy.2"] = null then [#"Trade - Copy.1"] else [#"Trade - Copy.1"] & ": " & Text.Trim([#"Trade - Copy.2"]))
in
#"Added Custom"
Best Regards,
Community Support Team _ Jing
If this post helps, please Accept it as Solution to help other members find it.
Hi @Anonymous
If the duplicates are subsets of the trade above them, you need to combine their father trade with them to make it clear which father trade they belong to. And this will create unique values for them. Use this new column in your report to display.
Transformation steps are as below.
let
Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WcsssSi3ISUxOLVaK1YlWCsgpzU3KzEvX9U4sKi5JzQMLKgBBUH5peoaupx9cIKQoMze/tATM9whzdNYNT83JTi0C811zUpNLijKTE3N0nYoS8zISc4kwJxYA", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [Trade = _t]),
#"Changed Type" = Table.TransformColumnTypes(Source,{{"Trade", type text}}),
#"Duplicated Column" = Table.DuplicateColumn(#"Changed Type", "Trade", "Trade - Copy"),
#"Split Column by Delimiter" = Table.SplitColumn(#"Duplicated Column", "Trade - Copy", Splitter.SplitTextByEachDelimiter({" "}, QuoteStyle.Csv, false), {"Trade - Copy.1", "Trade - Copy.2"}),
#"Replaced Value" = Table.ReplaceValue(#"Split Column by Delimiter","",null,Replacer.ReplaceValue,{"Trade - Copy.1"}),
#"Filled Down" = Table.FillDown(#"Replaced Value",{"Trade - Copy.1"}),
#"Added Custom" = Table.AddColumn(#"Filled Down", "Custom", each if [#"Trade - Copy.2"] = null then [#"Trade - Copy.1"] else [#"Trade - Copy.1"] & ": " & Text.Trim([#"Trade - Copy.2"]))
in
#"Added Custom"
Best Regards,
Community Support Team _ Jing
If this post helps, please Accept it as Solution to help other members find it.
you can either create a ragged hierarchy, or you can modify 34 and 35 to say "Plumbing-Karsten:Rough-IN" and "Plumbing-Karsten:Trimout" (for example).
Check out the July 2025 Power BI update to learn about new features.
This is your chance to engage directly with the engineering team behind Fabric and Power BI. Share your experiences and shape the future.
User | Count |
---|---|
71 | |
70 | |
43 | |
31 | |
26 |
User | Count |
---|---|
89 | |
49 | |
44 | |
38 | |
37 |