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.
Hello,
the table on the left (image below) contains duplicates in Column1 but the value in Column2 can have repeating values (or not).
From this table, I would like to display a table that would include only the duplicates in Column1 associated with each unique value in Column2 in order to obtain the right table.
How should I proceed?
I hope to have been clear enough.
Thank you in advance for your help.
Solved! Go to Solution.
Hi @Anonymous
You can do this in Power Query.
Download the PBIX file with the solution.
Create a composite column for Col1+Col2 e.g. A1, A1, A2 etc. Removing duplicates from this gets rid of multiple A1's etc.
Secondly, by counting the number of times a value in Col1 appears, you can then remove any row where the value only appears once.
This is the code
let
Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WclTSUTJUitVBZxmBWU5AljGY5QxkmcBZpmCWC5BlBmeZYxGDsFyBLAs4yxILy9AAzHQDMYFuiAUA", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [Column1 = _t, Column2 = _t]),
#"Changed Type" = Table.TransformColumnTypes(Source,{{"Column2", Int64.Type}}),
#"Added Custom" = Table.AddColumn(#"Changed Type", "Custom", each [Column1] & Text.From([Column2])),
#"Added Custom1" = Table.AddColumn(#"Added Custom", "Count Val", each List.Count(List.PositionOf(#"Added Custom"[Column1], [Column1] ,2))),
#"Filtered Rows" = Table.SelectRows(#"Added Custom1", each ([Count Val] <> 1)),
#"Removed Duplicates" = Table.Distinct(#"Filtered Rows", {"Custom"}),
#"Removed Columns" = Table.RemoveColumns(#"Removed Duplicates",{"Custom", "Count Val"})
in
#"Removed Columns"
This is the resulting table
Regards
Phil
Proud to be a Super User!
Hi @Anonymous
If you want a DAX method, it would be:
First add a column in original table to count the unique values in Column2 for each Column1 item.
Then create a new table with
Best Regards,
Community Support Team _ Jing
If this post helps, please Accept it as Solution to help other members find it.
Hi @Anonymous
If you want a DAX method, it would be:
First add a column in original table to count the unique values in Column2 for each Column1 item.
Then create a new table with
Best Regards,
Community Support Team _ Jing
If this post helps, please Accept it as Solution to help other members find it.
Hi @Anonymous
You can do this in Power Query.
Download the PBIX file with the solution.
Create a composite column for Col1+Col2 e.g. A1, A1, A2 etc. Removing duplicates from this gets rid of multiple A1's etc.
Secondly, by counting the number of times a value in Col1 appears, you can then remove any row where the value only appears once.
This is the code
let
Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WclTSUTJUitVBZxmBWU5AljGY5QxkmcBZpmCWC5BlBmeZYxGDsFyBLAs4yxILy9AAzHQDMYFuiAUA", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [Column1 = _t, Column2 = _t]),
#"Changed Type" = Table.TransformColumnTypes(Source,{{"Column2", Int64.Type}}),
#"Added Custom" = Table.AddColumn(#"Changed Type", "Custom", each [Column1] & Text.From([Column2])),
#"Added Custom1" = Table.AddColumn(#"Added Custom", "Count Val", each List.Count(List.PositionOf(#"Added Custom"[Column1], [Column1] ,2))),
#"Filtered Rows" = Table.SelectRows(#"Added Custom1", each ([Count Val] <> 1)),
#"Removed Duplicates" = Table.Distinct(#"Filtered Rows", {"Custom"}),
#"Removed Columns" = Table.RemoveColumns(#"Removed Duplicates",{"Custom", "Count Val"})
in
#"Removed Columns"
This is the resulting table
Regards
Phil
Proud to be a Super User!
@Anonymous , In a table visual if you take both of them as nont summarized, then you will get it
Or create a new table
New Table=
Summarize(Table, Table[Column1], Table[column2])
Thanks for your answer. Only I don't want it to display the Categories that have only one Value (here the Categories B and F). In short, I only want to see duplicates or triplicates displayed.
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 |
---|---|
70 | |
68 | |
43 | |
34 | |
26 |
User | Count |
---|---|
86 | |
50 | |
45 | |
38 | |
38 |