Join us at FabCon Atlanta from March 16 - 20, 2026, for the ultimate Fabric, Power BI, AI and SQL community-led event. Save $200 with code FABCOMM.
Register now!The Power BI Data Visualization World Championships is back! Get ahead of the game and start preparing now! Learn more
I have a scenario where I am wanting to determine what is the length of the longest word in a value.
| Value | Longest Word |
| A T & T | 1 |
| P B I | 1 |
| U S A United | 6 |
I'm sure it involves using the Text.Split and then somehow using Text.Length inside a List.Max, but I cannot for the life of me figure out how to achieve this. I'd love it if this were all performed in a single step rather than having multiple steps as the dataset Is quite large (300k+ records).
Any ideas?
Solved! Go to Solution.
Paste the below into a blank query in the advanced editor to see the steps.
You were definitely on the right track.
I don't think you need to worry too much about having it as a single step, having one line of code doesn't always make it perform better, the optimisations in the background take care a lot of that for you but I'm sure you could rework these steps to a single step if you wish.
let
Source = Table.FromRows(
Json.Document(
Binary.Decompress(
Binary.FromText(
"i45WclQIUYgpNTAwMlMIUYrViVYKUHBS8ASzQhWCFRwVQvMyS1JTlGJjAQ==",
BinaryEncoding.Base64
),
Compression.Deflate
)
),
let
_t = ((type nullable text) meta [Serialized.Text = true])
in
type table [Value = _t]
),
Duplicate = Table.DuplicateColumn(Source, "Value", "Value - Copy"),
Split = Table.SplitColumn(
Duplicate,
"Value - Copy",
Splitter.SplitTextByDelimiter(" ", QuoteStyle.Csv),
{"Value - Copy.1", "Value - Copy.2", "Value - Copy.3", "Value - Copy.4"}
),
Unpivot = Table.UnpivotOtherColumns(Split, {"Value"}, "Attribute", "Values"),
Group = Table.Group(Unpivot, {"Value"}, {{"MaxWord", each List.Max([Values]), type text}}),
AddLength = Table.AddColumn(Group, "Length", each Text.Length([MaxWord]), Int64.Type)
in
AddLength
Hope this helps.
| Have I solved your problem? Please click Accept as Solution so I don't keep coming back to this post, oh yeah, others may find it useful also ;). |
@KNP has a good solution but I'd like to suggest a single-step solution too.
Create a new custom column with this formula:
List.Max(List.Transform(Text.Split([Value], " "), each Text.Length(_)))
@KNP has a good solution but I'd like to suggest a single-step solution too.
Create a new custom column with this formula:
List.Max(List.Transform(Text.Split([Value], " "), each Text.Length(_)))
Paste the below into a blank query in the advanced editor to see the steps.
You were definitely on the right track.
I don't think you need to worry too much about having it as a single step, having one line of code doesn't always make it perform better, the optimisations in the background take care a lot of that for you but I'm sure you could rework these steps to a single step if you wish.
let
Source = Table.FromRows(
Json.Document(
Binary.Decompress(
Binary.FromText(
"i45WclQIUYgpNTAwMlMIUYrViVYKUHBS8ASzQhWCFRwVQvMyS1JTlGJjAQ==",
BinaryEncoding.Base64
),
Compression.Deflate
)
),
let
_t = ((type nullable text) meta [Serialized.Text = true])
in
type table [Value = _t]
),
Duplicate = Table.DuplicateColumn(Source, "Value", "Value - Copy"),
Split = Table.SplitColumn(
Duplicate,
"Value - Copy",
Splitter.SplitTextByDelimiter(" ", QuoteStyle.Csv),
{"Value - Copy.1", "Value - Copy.2", "Value - Copy.3", "Value - Copy.4"}
),
Unpivot = Table.UnpivotOtherColumns(Split, {"Value"}, "Attribute", "Values"),
Group = Table.Group(Unpivot, {"Value"}, {{"MaxWord", each List.Max([Values]), type text}}),
AddLength = Table.AddColumn(Group, "Length", each Text.Length([MaxWord]), Int64.Type)
in
AddLength
Hope this helps.
| Have I solved your problem? Please click Accept as Solution so I don't keep coming back to this post, oh yeah, others may find it useful also ;). |
This is good but I'd like to offer a suggestion to make it a bit better.
You can split into rows instead of columns to avoid the unpivot step and make the query more robust against new data that would need to be split into more columns.
The Power BI Data Visualization World Championships is back! Get ahead of the game and start preparing now!
Check out the November 2025 Power BI update to learn about new features.
| User | Count |
|---|---|
| 10 | |
| 6 | |
| 5 | |
| 4 | |
| 2 |