How to remove spaces in Power Query

In a previous post, we looked at various methods to remove additional spaces in Excel. One of the methods involved creating a custom function in Power Query. As this is a more advanced method, I wanted to go a bit deeper and describe the method to remove spaces in Power Query.

Table of Contents

Excel TRIM vs. Power Query Trim

Excel’s TRIM function removes leading spaces, trailing spaces, and multiple spaces from the middle (known as an inner trim) of a text string. It’s an excellent function for cleaning dirty data.

Excel version of TRIM

However, Power Query’s Trim function, by comparison, only removes leading and trailing spaces. The spaces in the middle of the string remain.

Power Query version of Trim

It’s rare we would ever want multiple spaces within a text string, yet they are not uncommon when dealing with dirty data. Therefore, the question is, how can we get Power Query to replicate Excel’s TRIM function capabilities?

Find and replace to remove double spaces

One option to solve this problem is to replace values. We can repeatedly use the replace values transformation on a column of text string until all the excess spaces have been removed.

To do this:

  • Select the column containing double spaces
  • Click Transform > Replace Values
  • In the Replace Values box, enter a double space in the Value to Find box, and a single space in the Replace with box.
    Transform Replace Values
  • Finally, click OK

If we have more than 3 spaces together, this will not remove all instances of excess spaces. Therefore, we need to repeat this action repeatedly until all excess spaces are removed.

While this method works, what if we refresh and there are 5 spaces, 8 spaces, or 23 spaces together? We just don’t know many times to undertake the transformation to ensure it provides the correct result. Instead, we need to find a better option.

Custom function to remove spaces in Power Query

Our goal is to remove double spaces in a column using a single Power Query transformation. It should not matter how many spaces there are. For this, we will use a custom function.

There are two main approaches to creating custom functions in Power Query:

  1. Create the transformations using the user interface, then convert it to a function
  2. Create the function from scratch by writing the M code ourselves

I usually advise the first method where possible, as it is easier to get started. However, for this transformation, it is easier to write the code with a little bit of formula knowledge.

For a more detailed guide on creating custom functions, check out this post: How to use Power Query Custom Functions

Power Query functions

The functions we are using in our solution are Text.Split, List.Select and Text.Combine.

Text.Split

Returns a list of text values after splitting the value based on a specific delimiter/separator,

Text.Split(text as text, separator as text) as list

More info: https://powerquery.how/text-split/

List.Select

Returns a list of values from a list that match the selection criteria.

List.Select(list as list, selection as function) as list

More info: https://powerquery.how/list-select/

Text.Combine

Returns the result of combining a list of text values into a single string, which can be joined with a separator between each element.

Text.Combine(texts as list, optional separator as nullable text) as text

More info: https://powerquery.how/text-combine/

Understanding the custom function

Using the 3 formulas listed above, we undertake a 3 step process:

  1. Split the text value into a list with the split occurring at each occurrence of the space character. This converts all spaces into empty strings
  2. Remove the empty strings from the list
  3. Re-join the list together and insert a single space between each word

These three steps create the same effect as Excel’s TRIM function.

We only require a single argument; the text string on which to perform the function.

(textValue as text)=>

let
    //Split the text at each space character
    SplitText = Text.Split(textValue," "),
    //Remove the blank items from the list
    ListNonBlankValues = List.Select(SplitText,each _<> ""),
    //Join the list with a space character between each item
    TextJoinList = Text.Combine(ListNonBlankValues," ")
in
    TextJoinList

Create the custom function

To create a custom function, perform the following steps:

  1. In Power Query, click Home > New Source (dropdown) > Other Sources > Blank Query
    Create a blank query
  2. Rename the query to fxTrim. You can call it anything you like. “fx” is commonly a used prefix to identify custom functions.
  3. Click View > Advanced Editor
  4. Enter the code above into the Advanced Editor window
  5. When finished, click Done
    Enter code into Advanced Editor

The function is now ready to use.

Using the custom function

Now let’s use the custom function on our Table.

  1. Click Add Column > Invoke Custom Function
  2. In the Invoke Custom Function window:
    • Provide the name of the new column to be created (Trimmed Supplier in the example below)
    • Select fxTrim from the list of functions
    • Enter the column on which to perform the transformation (Supplier in the example below)
  3. Finally, click OK.
Invoke Custom Function

Ta-Dah!

Custom Function to remove spaces in Power query

The new column now contains cleaned text values with no excess spaces. Woop Woop!!!

Still have spaces?

If you still have spaces, it’s likely they are either non-printing characters or non-breaking spaces. Apply the following transformations before apply the fxTrim function.

Remove non-printing characters with clean

Non-printing characters are items such as null, line-feed and carriage returns. They have character codes of 0 to 31. To remove non-printing characters:

  • Select the column
  • Click Transform > Clean from the ribbon

Covert non-breaking space character to space

The non-breaking space character (known as nbsp) is often found on web pages as a way to force white space onto the page. This has a character code of 160 and is not removed by the clean or trim transformations.

Visually, this character is a space, so let’s convert it into a space:

  • Select the column
  • Click Transform > Replace Values from the ribbon
  • In the Replace Values dialog box, click into the value to find box, then click Advanced option > Relace using special character > Insert special character > Non-breaking space. This will enter #(00A0) into the box. #(00A0) is Power Query code for a nbsp character
  • Enter a space into the replace with box
  • Click OK

Conclusion

It is a shame Power Query’s Trim function does not match Excel’s functionality. But thankfully, this doesn’t stop us. We can create our own function to remove unwanted spaces in Power Query.

And maybe, not having the same functionality actually makes things more flexible for us 😀

Related Posts:


Discover how you can automate your work with our Excel courses and tools.

Excel Academy

Excel Academy
The complete program for saving time by automating Excel.

Excel Automation Secrets

Excel Automation Secrets
Discover the 7-step framework for automating Excel.

Office Scripts Course

Office Scripts: Automate Excel Everywhere
Start using Office Scripts and Power Automate to automate Excel in new ways.

2 thoughts on “How to remove spaces in Power Query”

  1. Hey Mark,

    Gosh that’s a fun formula, thanks for sharing. I tried to think of an alternative, but it was hard to find. Here’s one I cooked up:

    = Table.AddColumn(
    Source, "Custom",
    let
    CustomFunction = (x as text) as text => if Text.Contains(x, " ") then @CustomFunction(Text.Replace(x, " " , " ") ) else x
    in each CustomFunction([MyText]) )

    Reply

Leave a Comment