Skip to main content
cancel
Showing results for 
Search instead for 
Did you mean: 

Register now to learn Fabric in free live sessions led by the best Microsoft experts. From Apr 16 to May 9, in English and Spanish.

Reply
vjnvinod
Impactful Individual
Impactful Individual

Power query to find the duplicate entry with specific condition

Hi All,

 

I need to create a coloumn in power query using a condition 

where

if 

Employee GUI coloumn is duplicate & Engagement ID coloumn is duplicate & Transaction date is duplicate but Hours are reversed let say -5 and 5

thn

show me that coloumn as No, else yes

 

how to do that, here the issue is with hours coloumn as i need to consider negative and postive of same number as Duplicate

so if hours=-5,5 meets the above if condition, hours should also be duplicate

Capture.PNG

 

 

1 ACCEPTED SOLUTION
Jimmy801
Community Champion
Community Champion

Hello @vjnvinod 

 

use Table.Group and then add a new column, where you check a) if it has more then 1 row and if the hours-column has all the same absolute number. in this case 3 row of hours with values - 5, 5, -5 would result in no

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WMlTSUXIEYgNDPSAyMgAydU2VYnWwykAkjIAsJ5CEKVzCBCxhDGQ5o0oYgyVMgCwXVAkjXEYZKsXGAgA=", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [#"Employee GUI" = _t, #"Engagemend ID" = _t, #"Transaction Date" = _t, Hours = _t]),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"Employee GUI", Int64.Type}, {"Engagemend ID", type text}, {"Transaction Date", type date}, {"Hours", Int64.Type}}),
    #"Grouped Rows" = Table.Group(#"Changed Type", {"Employee GUI", "Engagemend ID", "Transaction Date"}, {{"AllRows", each _, type table [Employee GUI=number, Engagemend ID=text, Transaction Date=date, Hours=number]}}),
    #"Added Custom" = Table.AddColumn(#"Grouped Rows", "Custom", each if Table.RowCount([AllRows])>1 and List.Accumulate([AllRows][Hours], [AllRows][Hours]{0}, (o,n)=> if Number.Abs(o)=Number.Abs(n) then Number.Abs(n) else 0)=Number.Abs([AllRows][Hours]{0}) then "no" else "yes"),
    #"Expanded AllRows" = Table.ExpandTableColumn(#"Added Custom", "AllRows", {"Hours"}, {"Hours"})
in
    #"Expanded AllRows"

 another approach would be to sum the hours and if the result is 0 write no. Here an example

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WMlTSUXIEYgNDPSAyMgAydU2VYnWwykAkjIAsJ5CEKVzCBCxhDGQ5o0oYgyVMgCwXVAkjXEYZKsXGAgA=", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [#"Employee GUI" = _t, #"Engagemend ID" = _t, #"Transaction Date" = _t, Hours = _t]),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"Employee GUI", Int64.Type}, {"Engagemend ID", type text}, {"Transaction Date", type date}, {"Hours", Int64.Type}}),
    #"Grouped Rows" = Table.Group(#"Changed Type", {"Employee GUI", "Engagemend ID", "Transaction Date"}, {{"AllRows", each _, type table [Employee GUI=number, Engagemend ID=text, Transaction Date=date, Hours=number]}}),
    #"Added Custom" = Table.AddColumn(#"Grouped Rows", "Custom", each if Table.RowCount([AllRows])>1 and List.Sum([AllRows][Hours])=0 then "no" else "yes"),
    #"Expanded AllRows" = Table.ExpandTableColumn(#"Added Custom", "AllRows", {"Hours"}, {"Hours"})
in
    #"Expanded AllRows"

Jimmy801_0-1607511588932.png

 

Copy paste this code to the advanced editor in a new blank query to see how the solution works.

If this post helps or solves your problem, please mark it as solution (to help other users find useful content and to acknowledge the work of users that helped you)
Kudoes are nice too

Have fun

Jimmy

View solution in original post

2 REPLIES 2
Jimmy801
Community Champion
Community Champion

Hello @vjnvinod 

 

use Table.Group and then add a new column, where you check a) if it has more then 1 row and if the hours-column has all the same absolute number. in this case 3 row of hours with values - 5, 5, -5 would result in no

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WMlTSUXIEYgNDPSAyMgAydU2VYnWwykAkjIAsJ5CEKVzCBCxhDGQ5o0oYgyVMgCwXVAkjXEYZKsXGAgA=", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [#"Employee GUI" = _t, #"Engagemend ID" = _t, #"Transaction Date" = _t, Hours = _t]),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"Employee GUI", Int64.Type}, {"Engagemend ID", type text}, {"Transaction Date", type date}, {"Hours", Int64.Type}}),
    #"Grouped Rows" = Table.Group(#"Changed Type", {"Employee GUI", "Engagemend ID", "Transaction Date"}, {{"AllRows", each _, type table [Employee GUI=number, Engagemend ID=text, Transaction Date=date, Hours=number]}}),
    #"Added Custom" = Table.AddColumn(#"Grouped Rows", "Custom", each if Table.RowCount([AllRows])>1 and List.Accumulate([AllRows][Hours], [AllRows][Hours]{0}, (o,n)=> if Number.Abs(o)=Number.Abs(n) then Number.Abs(n) else 0)=Number.Abs([AllRows][Hours]{0}) then "no" else "yes"),
    #"Expanded AllRows" = Table.ExpandTableColumn(#"Added Custom", "AllRows", {"Hours"}, {"Hours"})
in
    #"Expanded AllRows"

 another approach would be to sum the hours and if the result is 0 write no. Here an example

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WMlTSUXIEYgNDPSAyMgAydU2VYnWwykAkjIAsJ5CEKVzCBCxhDGQ5o0oYgyVMgCwXVAkjXEYZKsXGAgA=", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [#"Employee GUI" = _t, #"Engagemend ID" = _t, #"Transaction Date" = _t, Hours = _t]),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"Employee GUI", Int64.Type}, {"Engagemend ID", type text}, {"Transaction Date", type date}, {"Hours", Int64.Type}}),
    #"Grouped Rows" = Table.Group(#"Changed Type", {"Employee GUI", "Engagemend ID", "Transaction Date"}, {{"AllRows", each _, type table [Employee GUI=number, Engagemend ID=text, Transaction Date=date, Hours=number]}}),
    #"Added Custom" = Table.AddColumn(#"Grouped Rows", "Custom", each if Table.RowCount([AllRows])>1 and List.Sum([AllRows][Hours])=0 then "no" else "yes"),
    #"Expanded AllRows" = Table.ExpandTableColumn(#"Added Custom", "AllRows", {"Hours"}, {"Hours"})
in
    #"Expanded AllRows"

Jimmy801_0-1607511588932.png

 

Copy paste this code to the advanced editor in a new blank query to see how the solution works.

If this post helps or solves your problem, please mark it as solution (to help other users find useful content and to acknowledge the work of users that helped you)
Kudoes are nice too

Have fun

Jimmy

watkinnc
Super User
Super User

You could do this:

let

Source = Table.Group(TableName, {"Employee GUI", "Engagement ID", "Transaction Date", "Hours"}, {{"Count", each List.Count([Hours]), Int64.Type}, {"Details", each _, type table}}),

Unique = Table.AddColumn(Source, "Unique", each if [Count] > 1 then "No" else "Yes", type text),

Select = Table.SelectColumns(Unique, {"Details", "Unique"}),

Expand = Table.ExpandTableColumn(Select, "Details", {"Employee GUI", "Engagement ID", "Transaction Date"})

 

in Expand

--Nate

 


I’m usually answering from my phone, which means the results are visualized only in my mind. You’ll need to use my answer to know that it works—but it will work!!

Helpful resources

Announcements
Microsoft Fabric Learn Together

Microsoft Fabric Learn Together

Covering the world! 9:00-10:30 AM Sydney, 4:00-5:30 PM CET (Paris/Berlin), 7:00-8:30 PM Mexico City

PBI_APRIL_CAROUSEL1

Power BI Monthly Update - April 2024

Check out the April 2024 Power BI update to learn about new features.

April Fabric Community Update

Fabric Community Update - April 2024

Find out what's new and trending in the Fabric Community.

Top Solution Authors