I showed various methods to remove additional spaces in Excel in a previous post. 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 excess spaces in Power Query.
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.
Power Query’s Trim function, by comparison, only removes leading and trailing spaces; the spaces in the middle of the string remain.
It’s very rare we would ever want multiple spaces within a text string, yet they are not uncommon when dealing with dirty data. So, how can we get Power Query to replicate Excel’s capabilities?
Find and replace to remove double spaces
One option to solve this problem is to repeatedly use the replace values step on a 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 double spaces in the Value to Find box, and a single space in the Replace with box
- Finally, click OK
If you have more than 3 spaces together, this will not remove all instances of excess spaces. Therefore, we need to repeat this action until all excess spaces have been removed.
While this method works, what if we refresh and there are 5 spaces or 8 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
We want to remove double spaces in Power Query with a single transformation, no matter how many spaces there are. For this, we will use a custom function.
There are two approaches to creating custom functions in Power Query:
- Create the transformations using the user interface, then convert it to a function
- Create the function from scratch by writing the M code ourselves
I usually advise the first 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: Power Query – Custom Functions
Power Query functions
The functions we are using are:
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://docs.microsoft.com/en-us/powerquery-m/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://docs.microsoft.com/en-us/powerquery-m/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://docs.microsoft.com/en-us/powerquery-m/text-combine
Understanding the custom function
Using the 3 formulas listed above, we will undertake a 3 step process:
- 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
- Remove the empty strings from the list
- Re-join the list together and insert a single space between each word.
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:
- In Power Query, click Home > New Source (dropdown) > Other Sources > Blank Query
- Rename the query to fxTrim. You can call it anything you like, but “fx” is commonly a used prefix to identify custom functions.
- Click View > Advanced Editor
- Enter the code above into the Advanced Editor window
- When finished, click Done
The function is now ready to use.
Using the custom function
Now let’s use the custom function on our Table.
- Click Add Column > Invoke Custom Function
- In the Invoke Custom Function window:
- Provide the name of the new column to be created
- Select fxTrim from the list of functions
- Enter the column on which to perform the transformation.
- Finally, click OK.
Ta-Dah!
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 a non-breaking spaces. Apply the following transformations before the space removal steps detailed above.
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 (known as nbsp) character 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 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 window, 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 😀
What to know more about:
- Removing spaces in Excel? Check out this post: 7 ways to remove additional spaces in Excel
- Custom functions in Power Query? Check this out: Power Query: Custom Functions

Get our FREE VBA eBook of the 30 most useful Excel VBA macros.
Automate Excel so that you can save time and stop doing the jobs a trained monkey could do.
Don’t forget:
If you’ve found this post useful, or if you have a better approach, then please leave a comment below.
Do you need help adapting this to your needs?
I’m guessing the examples in this post didn’t exactly meet your situation. We all use Excel differently, so it’s impossible to write a post that will meet everybody’s needs. By taking the time to understand the techniques and principles in this post (and elsewhere on this site) you should be able to adapt it to your needs.
But, if you’re still struggling you should:
- Read other blogs, or watch YouTube videos on the same topic. You will benefit much more by discovering your own solutions.
- Ask the ‘Excel Ninja’ in your office. It’s amazing what things other people know.
- Ask a question in a forum like Mr Excel, or the Microsoft Answers Community. Remember, the people on these forums are generally giving their time for free. So take care to craft your question, make sure it’s clear and concise. List all the things you’ve tried, and provide screenshots, code segments and example workbooks.
- Use Excel Rescue, who are my consultancy partner. They help by providing solutions to smaller Excel problems.
What next?
Don’t go yet, there is plenty more to learn on Excel Off The Grid. Check out the latest posts:
Hi Mark,
Sometimes, it’s simpler to pre-process data in Excel, before calling Power Query. Of course, it depends on use case but, if you can create a table in Excel (or if you’re already sourcing from a table), just add a column with the Excel Trim function for each column of data that needs it.
Then launch PQ and work with the trimmed columns. 🙂
Cheers,
Mitch
Hi Mitch – very true. If it can easily be cleaned before getting to Power Query, then do it. No point pushing in dirty data that could easily be fixed to then have to clean it in PQ.