Check your eligibility for this 50% exam voucher offer and join us for free live learning sessions to get prepared for Exam DP-700.
Get StartedDon't miss out! 2025 Microsoft Fabric Community Conference, March 31 - April 2, Las Vegas, Nevada. Use code MSCUST for a $150 discount. Prices go up February 11th. Register now.
Hello Community,
Is there a way in PowerQuery or Excel to conditionally remove duplicates?
Very quick context there are employee id numbers, their planned hours for the year, the financial year and Hrs of absence. However the raw lists their yearly hours on every row, i want to only keep one per financial year.
I've explored the forum and tried using a helper column but have not had any success.
Any help is greatly appreciated.
Solved! Go to Solution.
@Anonymous here is the example power query script which you can use to achieve it.
let
Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WMlTSUTI0ABFA7BZpaKYUq4MkaoRP1BxV1BhZFKTECCRqgmwCXNQUqyh2E/Cai12tBVa1lljdABSNBQA=", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type text) meta [Serialized.Text = true]) in type table [Emp = _t, Planned = _t, Hours = _t, Year = _t]),
#"Changed Type" = Table.TransformColumnTypes(Source,{{"Emp", Int64.Type}, {"Planned", Int64.Type}, {"Hours", Int64.Type}, {"Year", type text}}),
#"Grouped Rows" = Table.Group(#"Changed Type", {"Emp", "Year"}, {{"Rank", each Table.AddIndexColumn(_, "Rank", 1)}}),
#"Expanded Rank" = Table.ExpandTableColumn(#"Grouped Rows", "Rank", {"Hours", "Planned", "Rank"}, {"Hours", "Planned", "Rank.1"}),
#"Added Custom" = Table.AddColumn(#"Expanded Rank", "New Planned", each (if [Rank.1] = 1 then [Planned] else null), type number),
#"Removed Columns" = Table.RemoveColumns(#"Added Custom",{"Planned", "Rank.1"}),
#"Changed Type1" = Table.TransformColumnTypes(#"Removed Columns",{{"Hours", Int64.Type}})
in
#"Changed Type1"
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.
@Anonymous here is the example power query script which you can use to achieve it.
let
Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WMlTSUTI0ABFA7BZpaKYUq4MkaoRP1BxV1BhZFKTECCRqgmwCXNQUqyh2E/Cai12tBVa1lljdABSNBQA=", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type text) meta [Serialized.Text = true]) in type table [Emp = _t, Planned = _t, Hours = _t, Year = _t]),
#"Changed Type" = Table.TransformColumnTypes(Source,{{"Emp", Int64.Type}, {"Planned", Int64.Type}, {"Hours", Int64.Type}, {"Year", type text}}),
#"Grouped Rows" = Table.Group(#"Changed Type", {"Emp", "Year"}, {{"Rank", each Table.AddIndexColumn(_, "Rank", 1)}}),
#"Expanded Rank" = Table.ExpandTableColumn(#"Grouped Rows", "Rank", {"Hours", "Planned", "Rank"}, {"Hours", "Planned", "Rank.1"}),
#"Added Custom" = Table.AddColumn(#"Expanded Rank", "New Planned", each (if [Rank.1] = 1 then [Planned] else null), type number),
#"Removed Columns" = Table.RemoveColumns(#"Added Custom",{"Planned", "Rank.1"}),
#"Changed Type1" = Table.TransformColumnTypes(#"Removed Columns",{{"Hours", Int64.Type}})
in
#"Changed Type1"
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.
March 31 - April 2, 2025, in Las Vegas, Nevada. Use code MSCUST for a $150 discount!
Check out the January 2025 Power BI update to learn about new features in Reporting, Modeling, and Data Connectivity.
User | Count |
---|---|
119 | |
82 | |
47 | |
42 | |
33 |
User | Count |
---|---|
190 | |
79 | |
72 | |
49 | |
46 |