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

If any duplicates values are present in the column, add 0.1 to one of the values

I have a column "Value" with duplicate values. For example if I have 2 values in the column as 1 and 1, then add 0.1 to one of the values so the values become 1.1 and 1. How do we solve in power query

kruthikav_0-1652871575215.png

 

1 ACCEPTED SOLUTION
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("i45WMlSK1YlWMgKThkikEQZpDCZNwKQpmDQDk+Yw8VgA", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [Value = _t]),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"Value", Int64.Type}}),
    #"Added Index" = Table.AddIndexColumn(#"Changed Type", "Index", 0, 1, Int64.Type),
    #"Grouped Rows" = Table.Group(#"Added Index", {"Value"}, {{"Temp", each _, type table [Value=nullable number, Index=number]}}),
    #"Removed Columns" = Table.RemoveColumns(#"Grouped Rows",{"Value"}),
    #"Added Custom" = Table.AddColumn(#"Removed Columns", "Custom", each Table.AddIndexColumn([Temp],"Index1",0,0.1)),
    #"Removed Columns1" = Table.RemoveColumns(#"Added Custom",{"Temp"}),
    #"Expanded Custom" = Table.ExpandTableColumn(#"Removed Columns1", "Custom", {"Value", "Index", "Index1"}, {"Value", "Index", "Index1"}),
    Custom1 = Table.ReplaceValue(#"Expanded Custom",each [Value],each [Value]+[Index1],Replacer.ReplaceValue,{"Value"}),
    #"Removed Columns3" = Table.RemoveColumns(Custom1,{"Index1"}),
    #"Sorted Rows" = Table.Sort(#"Removed Columns3",{{"Index", Order.Ascending}}),
    #"Removed Columns2" = Table.RemoveColumns(#"Sorted Rows",{"Index"})
in
    #"Removed Columns2"

 

View solution in original post

2 REPLIES 2
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("i45WMlSK1YlWMgKThkikEQZpDCZNwKQpmDQDk+Yw8VgA", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [Value = _t]),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"Value", Int64.Type}}),
    #"Added Index" = Table.AddIndexColumn(#"Changed Type", "Index", 0, 1, Int64.Type),
    #"Grouped Rows" = Table.Group(#"Added Index", {"Value"}, {{"Temp", each _, type table [Value=nullable number, Index=number]}}),
    #"Removed Columns" = Table.RemoveColumns(#"Grouped Rows",{"Value"}),
    #"Added Custom" = Table.AddColumn(#"Removed Columns", "Custom", each Table.AddIndexColumn([Temp],"Index1",0,0.1)),
    #"Removed Columns1" = Table.RemoveColumns(#"Added Custom",{"Temp"}),
    #"Expanded Custom" = Table.ExpandTableColumn(#"Removed Columns1", "Custom", {"Value", "Index", "Index1"}, {"Value", "Index", "Index1"}),
    Custom1 = Table.ReplaceValue(#"Expanded Custom",each [Value],each [Value]+[Index1],Replacer.ReplaceValue,{"Value"}),
    #"Removed Columns3" = Table.RemoveColumns(Custom1,{"Index1"}),
    #"Sorted Rows" = Table.Sort(#"Removed Columns3",{{"Index", Order.Ascending}}),
    #"Removed Columns2" = Table.RemoveColumns(#"Sorted Rows",{"Index"})
in
    #"Removed Columns2"

 

You can save quite a few steps by adding an index during grouping like this:

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WMlSK1YlWMgKThkikEQZpDCZNwKQpmDQDk+Yw8VgA", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [Value = _t]),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"Value", Int64.Type}}),
    #"Grouped Rows" = Table.Group(#"Changed Type", {"Value"}, {{"SubTable", each Table.AddIndexColumn(_, "Incr", 0, 0.1), type table [Value=nullable number, Incr=nullable number]}}),
    #"Expanded SubTable" = Table.ExpandTableColumn(#"Grouped Rows", "SubTable", {"Incr"}, {"Incr"}),
    #"Added Custom" = Table.AddColumn(#"Expanded SubTable", "AddIncr", each [Value]+[Incr], type number)
in
    #"Added Custom"

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