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
SubodhPatra
Frequent Visitor

Replace duplicate actions value except the first item for a user

Hi,

I am new to Power Query and got stucked to transform the data in Actions column for duplicate entries except the first one. The data is as follows

 

Mobile NumberActionsDate
919191919191initial_items20-Jul-2022
919191919191like20-Jul-2022
919191919191initial_items25-Jul-2022
919191919191like25-Jul-2022
919191919191like29-Jul-2022
919191919191initial_items06-Aug-2022
919191919191initial_items09-Aug-2022
919191919191like09-Aug-2022
919191919191initial_items22-Aug-2022
919191919191like22-Aug-2022

 

The requirement is to change "initial_items" in Actions column to be replaced to "more_items" except the first entry i.e. 20-Jul-2022. The expected result would be as below:

 

Mobile NumberActionsDate
919191919191initial_items20-Jul-2022
919191919191like20-Jul-2022
919191919191more_items25-Jul-2022
919191919191like25-Jul-2022
919191919191like29-Jul-2022
919191919191more_items06-Aug-2022
919191919191more_items09-Aug-2022
919191919191like09-Aug-2022
919191919191more_items22-Aug-2022
919191919191like22-Aug-2022

 

Please help me.

 

1 ACCEPTED SOLUTION

Hi Vijay,

 

Many many thanks from the bottom of my heart!

The code is working fine and I was eagerly waiting for your reply.

Really, you are a "Super User".

 

With Regards,

Subodh

View solution in original post

4 REPLIES 4
Vijay_A_Verma
Super User
Super User

See the working here - Open a blank query - Home - Advanced Editor - Remove everything from there and paste the below code to test (later on when you use the query on your dataset, you will have to change the source appropriately. If you have columns other than these, then delete Changed type step and do a Changed type for complete table from UI again)

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WsjREQCUdpcy8zJLMxJz4zJLU3GIg38hA16s0R9fISClWB0NxTmZ2KiE1GAaaEmEgMWosSbDUTNexNJ1ItZZ41ELtxqcEw79GhM1DUhMLAA==", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [#"Mobile Number" = _t, Actions = _t, Date = _t]),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"Mobile Number", Int64.Type}, {"Actions", type text}, {"Date", type date}}),
    #"Added Index" = Table.AddIndexColumn(#"Changed Type", "Index", 0, 1, Int64.Type),
    #"Filtered Rows" = Table.SelectRows(#"Added Index", each ([Actions] = "initial_items")),
    #"Removed Top Rows" = Table.Skip(#"Filtered Rows",1),
    #"Merged Queries" = Table.NestedJoin(#"Added Index", {"Index"}, #"Removed Top Rows", {"Index"}, "Removed Top Rows", JoinKind.LeftOuter),
    #"Expanded Removed Top Rows" = Table.ExpandTableColumn(#"Merged Queries", "Removed Top Rows", {"Index"}, {"Index.1"}),
    Custom1 = Table.ReplaceValue(#"Expanded Removed Top Rows",each [Actions],each if [Index.1] <> null then "more_items" else [Actions],Replacer.ReplaceValue,{"Actions"}),
    #"Sorted Rows" = Table.Sort(Custom1,{{"Index", Order.Ascending}}),
    #"Removed Columns" = Table.RemoveColumns(#"Sorted Rows",{"Index.1", "Index"})
in
    #"Removed Columns"

 👍 It's been a pleasure to help you | Help Hours: 11 AM to 9 PM (UTC+05:30)

How to get your questions answered quickly -- How to provide sample data

Hi Vijay,

Thanks for the Power Query code!

It is working fine for a single user (919191919191) but I have more than one users in the table.

 

Requesting you to modify the code for multiple users.

Here it is

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WsjREQCUdpcy8zJLMxJz4zJLU3GIg38hA16s0R9fISClWB0NxTmZ2KiE1GAaaEmEgMWosSbDUTNexNJ1YBxLhY0sqm2dkhMNAIyJC2YgUS8k1EFcIIpmHUBILAA==", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [#"Mobile Number" = _t, Actions = _t, Date = _t]),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"Mobile Number", type text}, {"Actions", type text}, {"Date", type date}}),
    #"Added Index" = Table.AddIndexColumn(#"Changed Type", "Index", 0, 1, Int64.Type),
    #"Grouped Rows" = Table.Group(#"Added Index", {"Mobile Number"}, {{"AllRows", each _}}),
    fxProcess=(Tbl)=>
    let
        #"Filtered Rows" = Table.SelectRows(Tbl, each ([Actions] = "initial_items")),
        #"Removed Top Rows" = Table.Skip(#"Filtered Rows",1),
        #"Merged Queries" = Table.NestedJoin(Tbl, {"Index"}, #"Removed Top Rows", {"Index"}, "Removed Top Rows", JoinKind.LeftOuter),
        #"Expanded Removed Top Rows" = Table.ExpandTableColumn(#"Merged Queries", "Removed Top Rows", {"Index"}, {"Index.1"}),
        Custom2 = Table.ReplaceValue(#"Expanded Removed Top Rows",each [Actions],each if [Index.1] <> null then "more_items" else [Actions],Replacer.ReplaceValue,{"Actions"}),
        #"Removed Columns" = Table.RemoveColumns(Custom2,{"Index.1"})
    in
        #"Removed Columns",
    #"Added Custom" = Table.AddColumn(#"Grouped Rows", "Custom", each fxProcess([AllRows])),
    #"Removed Columns" = Table.RemoveColumns(#"Added Custom",{"AllRows"}),
    #"Expanded Custom" = Table.ExpandTableColumn(#"Removed Columns", "Custom", {"Actions", "Date", "Index"}, {"Actions", "Date", "Index"}),
    #"Sorted Rows" = Table.Sort(#"Expanded Custom",{{"Index", Order.Ascending}}),
    #"Removed Columns1" = Table.RemoveColumns(#"Sorted Rows",{"Index"})
in
    #"Removed Columns1"

 👍 It's been a pleasure to help you | Help Hours: 11 AM to 9 PM (UTC+05:30)

How to get your questions answered quickly -- How to provide sample data

Hi Vijay,

 

Many many thanks from the bottom of my heart!

The code is working fine and I was eagerly waiting for your reply.

Really, you are a "Super User".

 

With Regards,

Subodh

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
Top Kudoed Authors