Power BI is turning 10, and we’re marking the occasion with a special community challenge. Use your creativity to tell a story, uncover trends, or highlight something unexpected.
Get startedJoin us for an expert-led overview of the tools and concepts you'll need to become a Certified Power BI Data Analyst and pass exam PL-300. Register now.
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:
Source | Min | Max |
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.55 | 4 | 10.55 |
0 to 11.58 to 5 to 11.58 to 5 | 5 | 11.58 |
9.87 to 9.76 | 9.76 | 9.87 |
8.77 to 8.77 | 8.77 | |
10.27 | 10.27 | |
9.87 to 6.99 to 9.89 to 6.88 | 6.88 | 9.89 |
Solved! Go to Solution.
@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"
@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"
This is your chance to engage directly with the engineering team behind Fabric and Power BI. Share your experiences and shape the future.
Check out the June 2025 Power BI update to learn about new features.
User | Count |
---|---|
64 | |
56 | |
54 | |
36 | |
34 |
User | Count |
---|---|
84 | |
73 | |
55 | |
45 | |
43 |