cancel
Showing results for 
Search instead for 
Did you mean: 

Fabric is Generally Available. Browse Fabric Presentations. Work towards your Fabric certification with the Cloud Skills Challenge.

Reply
Cyrilbrd
Helper IV
Helper IV

Create two custom columns MIN and MAX from a string

Given in column "Source" a mix of numbers with " to " as a delimiter.
Expected results:

The MIN column should return the smallest value 0 excluded.
The MAX column should return the biggest value.
If the value is unique OR if the MIN and the MAX are the same, only MIN should appear.

Example source with expected result:

SourceMinMax
9 to 10 to 4 to 10.55 to 9 to 10 to 4 to 10.55 to 9 to 10 to 4 to 10.55410.55
0 to 11.58 to 5 to 11.58 to 5511.58
9.87 to 9.769.769.87
8.77 to 8.778.77 
10.2710.27 
9.87 to 6.99 to 9.89 to 6.886.889.89
1 ACCEPTED SOLUTION
amitchandak
Super User
Super User

@Cyrilbrd , Try this power Query code. Add in blank Query and check

 

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("lU1bDoAwCLvKwrchbtkGnGXZGfzx/pHH1PjpB7S0TRkDJJ1HyrvtGhRbM/LPgA2qTvC5DXA/Z2xspH0vTdq44GlBJu9G6mo8wOQ2I7ltqPqC5J6+LBSvy6vehR1FopglbmYNLTAV5rwA", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [Source = _t, Min = _t, Max = _t]),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"Source", type text}, {"Min", type number}, {"Max", type number}}),
    #"Added Custom" = Table.AddColumn(#"Changed Type", "Custom", each List.Min ( List.RemoveItems( List.Transform( Text.Split( Text.Replace(Text.Replace([Source], "to "," "), "  "," "), " ") , each Number.FromText(_)) , {0}))),
    #"Added Custom1" = Table.AddColumn(#"Added Custom", "Custom.1", each if  List.Max ( List.RemoveItems( List.Transform( Text.Split( Text.Replace(Text.Replace([Source], "to "," "), "  "," "), " ") , each Number.FromText(_)) , {0})) = List.Min ( List.RemoveItems( List.Transform( Text.Split( Text.Replace(Text.Replace([Source], "to "," "), "  "," "), " ") , each Number.FromText(_)) , {0})) then null else List.Max ( List.RemoveItems( List.Transform( Text.Split( Text.Replace(Text.Replace([Source], "to "," "), "  "," "), " ") , each Number.FromText(_)) , {0})))
in
    #"Added Custom1"

View solution in original post

1 REPLY 1
amitchandak
Super User
Super User

@Cyrilbrd , Try this power Query code. Add in blank Query and check

 

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("lU1bDoAwCLvKwrchbtkGnGXZGfzx/pHH1PjpB7S0TRkDJJ1HyrvtGhRbM/LPgA2qTvC5DXA/Z2xspH0vTdq44GlBJu9G6mo8wOQ2I7ltqPqC5J6+LBSvy6vehR1FopglbmYNLTAV5rwA", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [Source = _t, Min = _t, Max = _t]),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"Source", type text}, {"Min", type number}, {"Max", type number}}),
    #"Added Custom" = Table.AddColumn(#"Changed Type", "Custom", each List.Min ( List.RemoveItems( List.Transform( Text.Split( Text.Replace(Text.Replace([Source], "to "," "), "  "," "), " ") , each Number.FromText(_)) , {0}))),
    #"Added Custom1" = Table.AddColumn(#"Added Custom", "Custom.1", each if  List.Max ( List.RemoveItems( List.Transform( Text.Split( Text.Replace(Text.Replace([Source], "to "," "), "  "," "), " ") , each Number.FromText(_)) , {0})) = List.Min ( List.RemoveItems( List.Transform( Text.Split( Text.Replace(Text.Replace([Source], "to "," "), "  "," "), " ") , each Number.FromText(_)) , {0})) then null else List.Max ( List.RemoveItems( List.Transform( Text.Split( Text.Replace(Text.Replace([Source], "to "," "), "  "," "), " ") , each Number.FromText(_)) , {0})))
in
    #"Added Custom1"

Helpful resources

Announcements
PBI November 2023 Update Carousel

Power BI Monthly Update - November 2023

Check out the November 2023 Power BI update to learn about new features.

Community News

Fabric Community News unified experience

Read the latest Fabric Community announcements, including updates on Power BI, Synapse, Data Factory and Data Activator.

Power BI Fabric Summit Carousel

The largest Power BI and Fabric virtual conference

130+ sessions, 130+ speakers, Product managers, MVPs, and experts. All about Power BI and Fabric. Attend online or watch the recordings.

Top Solution Authors
Top Kudoed Authors