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

The ultimate Microsoft Fabric, Power BI, Azure AI & SQL learning event! Join us in Las Vegas from March 26-28, 2024. Use code MSCUST for a $100 discount. Register Now

Reply
REgulus87
New Member

Eliminar duplicados cumpliendo criterios

Hola equipo!

Necesito de su ayuda! Tengo un conjunto de datos en los cuales necesitaria eliminar duplicados pero que se cumplan ciertos criterios. Eliminar los numeros de instalacion duplicados, pero donde la fecha de creacion y cierre sea la misma (mismo dia, mismo mes y mismo año), el status sea closed conservando el ultimo por su hora de creacion.

 

Ejemplo de tabla:

InstalacionMantenimientoStatusCreacionCierre
1935843098756234Finished05/05/2023 9:2012/05/2023 10:00
1935843096352874Closed01/04/2023 10:0001/04/2023 11:00
1935843097463154Closed01/04/2023 9:3001/04/2023 9:40
1935843094768213Closed01/04/2023 9:0001/04/2023 9:10
1935843091736455Closed03/03/2023 9:1503/03/2023 9:25
1935843099664215Finished03/03/2023 10:0007/03/2023 17:00

 

La tabla deberia quedar asi:

 

InstalacionMantenimientoStatusCreacionCierre
1935843098756234Finished05/05/2023 9:2012/05/2023 10:00
1935843096352874Closed01/04/2023 10:0001/04/2023 11:00
1935843099664215Finished03/03/2023 10:0007/03/2023 17:00

 

En el caso de que exista un finished y un closed con la misma fecha de creacion (dia, mes y año) deberia quedarme con el Finished eliminando el closed.

 

Cualquier ayuda sea bienvenida. 

Muchas gracias!!

1 ACCEPTED SOLUTION
v-yanjiang-msft
Community Support
Community Support

Hi @REgulus87 ,

According to your description, here's my solution.

1. Create a custom column.

if Table.RowCount(Table.SelectRows(#"Changed Type",(x)=>DateTime.Date(x[Creation])=DateTime.Date([Creation]) and DateTime.Date(x[Closing])=DateTime.Date([Closing])))=1 or [Status]="Finished" then 1 else if [Creation]=List.Max(Table.SelectRows(#"Changed Type",(x)=>DateTime.Date(x[Creation])=DateTime.Date([Creation]) and DateTime.Date(x[Closing])=DateTime.Date([Closing]))[Creation]) then 1 else ""

Result:

vyanjiangmsft_0-1684226088272.png

2. Filter the Custom column, only select value 1, then remove the Custom column.

vyanjiangmsft_1-1684226121282.png

Here's the whole code, you can copy-paste in a blank query to see the steps. 

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("ddE9C8IwEIDhv1I6F5L7TC6bCG6Ce+mmYEF06P8HU6mxxWY7XriHI+n7FowkMvm2ay0GUSTO42l8jtP9ds2jOHHokRpL6JP3zeGcK+A3wxyXPnRbUEkwhhk8Pl7ThwPH/3vrDHUusBLIPmeJdjRLXMM4aESgCrZ3miWoYRBIWWSNkaOyJgULv4pSwUyVEWT7DYXbvlvxZKmX7A1v", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [Installation = _t, Maintenance = _t, Status = _t, Creation = _t, Closing = _t]),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"Installation", Int64.Type}, {"Maintenance", Int64.Type}, {"Status", type text}, {"Creation", type datetime}, {"Closing", type datetime}}),
    #"Added Custom" = Table.AddColumn(#"Changed Type", "Custom", each if Table.RowCount(Table.SelectRows(#"Changed Type",(x)=>DateTime.Date(x[Creation])=DateTime.Date([Creation]) and DateTime.Date(x[Closing])=DateTime.Date([Closing])))=1 or [Status]="Finished" then 1 else if [Creation]=List.Max(Table.SelectRows(#"Changed Type",(x)=>DateTime.Date(x[Creation])=DateTime.Date([Creation]) and DateTime.Date(x[Closing])=DateTime.Date([Closing]))[Creation]) then 1 else ""),
    #"Filtered Rows" = Table.SelectRows(#"Added Custom", each ([Custom] = 1)),
    #"Removed Columns" = Table.RemoveColumns(#"Filtered Rows",{"Custom"})
in
    #"Removed Columns"

I attach my file below for your reference.

 

If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.

Best regards,

Community Support Team_yanjiang

View solution in original post

2 REPLIES 2
v-yanjiang-msft
Community Support
Community Support

Hi @REgulus87 ,

According to your description, here's my solution.

1. Create a custom column.

if Table.RowCount(Table.SelectRows(#"Changed Type",(x)=>DateTime.Date(x[Creation])=DateTime.Date([Creation]) and DateTime.Date(x[Closing])=DateTime.Date([Closing])))=1 or [Status]="Finished" then 1 else if [Creation]=List.Max(Table.SelectRows(#"Changed Type",(x)=>DateTime.Date(x[Creation])=DateTime.Date([Creation]) and DateTime.Date(x[Closing])=DateTime.Date([Closing]))[Creation]) then 1 else ""

Result:

vyanjiangmsft_0-1684226088272.png

2. Filter the Custom column, only select value 1, then remove the Custom column.

vyanjiangmsft_1-1684226121282.png

Here's the whole code, you can copy-paste in a blank query to see the steps. 

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("ddE9C8IwEIDhv1I6F5L7TC6bCG6Ce+mmYEF06P8HU6mxxWY7XriHI+n7FowkMvm2ay0GUSTO42l8jtP9ds2jOHHokRpL6JP3zeGcK+A3wxyXPnRbUEkwhhk8Pl7ThwPH/3vrDHUusBLIPmeJdjRLXMM4aESgCrZ3miWoYRBIWWSNkaOyJgULv4pSwUyVEWT7DYXbvlvxZKmX7A1v", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [Installation = _t, Maintenance = _t, Status = _t, Creation = _t, Closing = _t]),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"Installation", Int64.Type}, {"Maintenance", Int64.Type}, {"Status", type text}, {"Creation", type datetime}, {"Closing", type datetime}}),
    #"Added Custom" = Table.AddColumn(#"Changed Type", "Custom", each if Table.RowCount(Table.SelectRows(#"Changed Type",(x)=>DateTime.Date(x[Creation])=DateTime.Date([Creation]) and DateTime.Date(x[Closing])=DateTime.Date([Closing])))=1 or [Status]="Finished" then 1 else if [Creation]=List.Max(Table.SelectRows(#"Changed Type",(x)=>DateTime.Date(x[Creation])=DateTime.Date([Creation]) and DateTime.Date(x[Closing])=DateTime.Date([Closing]))[Creation]) then 1 else ""),
    #"Filtered Rows" = Table.SelectRows(#"Added Custom", each ([Custom] = 1)),
    #"Removed Columns" = Table.RemoveColumns(#"Filtered Rows",{"Custom"})
in
    #"Removed Columns"

I attach my file below for your reference.

 

If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.

Best regards,

Community Support Team_yanjiang

Thank you!!!!

Helpful resources

Announcements
Fabric Community Conference

Microsoft Fabric Community Conference

Join us at our first-ever Microsoft Fabric Community Conference, March 26-28, 2024 in Las Vegas with 100+ sessions by community experts and Microsoft engineering.

February 2024 Update Carousel

Power BI Monthly Update - February 2024

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

Fabric Career Hub

Microsoft Fabric Career Hub

Explore career paths and learn resources in Fabric.

Fabric Partner Community

Microsoft Fabric Partner Community

Engage with the Fabric engineering team, hear of product updates, business opportunities, and resources in the Fabric Partner Community.

Top Solution Authors
Top Kudoed Authors