cancel
Showing results for 
Search instead for 
Did you mean: 
Reply
rajatsharma87
New Member

how to create a New column to get the last status of the duplicate values for all the duplicate rows

How to Filter data?

0 upvotes0
 
Arushi · 
Lecture 8
 · A few seconds ago

Suppose we have a data like

User_ID     Result

1                    f

1                   f

1                  p

2                 f

2                 p

3                 f

4                 f

5                p

 

If any user_id which is duplicate has 'p' as result, then the third column should have p for all the rows for that user_id. Else copy the value of result column into the new column:

For example the solution for of the above is

 

User_ID     Result         New_Column

1                    f                      p

1                   f                       p

1                  p                       p

2                 f                        p

2                 p                       p

3                 f                        f                       

3                 f                       f

4                p                       p

1 ACCEPTED SOLUTION
alannavarro
Resolver I
Resolver I

Hello, hope it works

 

let
//Source data from data example.
Source = Excel.CurrentWorkbook(){[Name="Table1"]}[Content],
//Group by User_ID column.
#"Grouped Rows" = Table.Group(Source, {"User_ID"}, {{"Count", each _, type table [User_ID=number, Result=text]}}),
//Create function to do the check.
check =
(check_function)=>
let
Custom1 = Table.AddColumn(check_function,"Check", each if List.Contains(check_function[Result],"p") then "p" else [Result])
in
Custom1,
//Call the function check to add new column name "Check Duplicates".
Combine = Table.AddColumn(#"Grouped Rows","Check", each check([Count])),
#"Removed Other Columns" = Table.SelectColumns(Combine,{"Check"}),
#"Expanded Check" = Table.ExpandTableColumn(#"Removed Other Columns", "Check", {"User_ID", "Result", "Check"}, {"User_ID", "Result", "Check Duplicate Values"})
in
#"Expanded Check"

View solution in original post

4 REPLIES 4
alannavarro
Resolver I
Resolver I

mmm I think that it would be to add the columns names in here:
#"Grouped Rows" = Table.Group(Source, {"User_ID"}, {{"Count", each _, type table [User_ID=number, Result=text]}}),
example...
#"Grouped Rows" = Table.Group(Source, {"User_ID"}, {{"Count", each _, type table [User_ID=number, Result=text, NewColumn1 = text, Newcolumn2=number]}}),

Thanks a lot , That worked.

alannavarro
Resolver I
Resolver I

Hello, hope it works

 

let
//Source data from data example.
Source = Excel.CurrentWorkbook(){[Name="Table1"]}[Content],
//Group by User_ID column.
#"Grouped Rows" = Table.Group(Source, {"User_ID"}, {{"Count", each _, type table [User_ID=number, Result=text]}}),
//Create function to do the check.
check =
(check_function)=>
let
Custom1 = Table.AddColumn(check_function,"Check", each if List.Contains(check_function[Result],"p") then "p" else [Result])
in
Custom1,
//Call the function check to add new column name "Check Duplicates".
Combine = Table.AddColumn(#"Grouped Rows","Check", each check([Count])),
#"Removed Other Columns" = Table.SelectColumns(Combine,{"Check"}),
#"Expanded Check" = Table.ExpandTableColumn(#"Removed Other Columns", "Check", {"User_ID", "Result", "Check"}, {"User_ID", "Result", "Check Duplicate Values"})
in
#"Expanded Check"

Thank you so much for the solution. Now using that code the problem I am facing it is tha it removes other 20 columns I have in the table. How can I get all the other columns as well ?

Helpful resources

Announcements
Winner of T-Shirt Design

Power BI T-Shirt Design Challenge 2023

Find out who won the T-Shirt Design Challenge and the top 3 finalists.

March 2023 Update3

Power BI March 2023 Update

Find out more about the March 2023 update.

Top Kudoed Authors