Power Query Replacing more than one comma

hatstand

Well-known Member
Joined
Mar 17, 2005
Messages
778
Office Version
  1. 2016
Platform
  1. Windows
Hi All,

I have a file with varying amounts of words and commas in each row. To tidy things up and place one comma in front of every word (later to be split by delimiter). I am replacing every pair of commas with a single commas until the job is done. My problem is that it takes 20 lines as per below to get the job done. Is there a simpler method like a ",*". Obviously this won't work and I'm not up to speed with M code yet. Thanks for any pointers.

#"Replaced Value7" = Table.ReplaceValue(#"Replaced Value6",",,,,",",",Replacer.ReplaceText,{"Column1"}),
 

Excel Facts

Create a chart in one keystroke
Select the data and press Alt+F1 to insert a default chart. You can change the default chart to any chart type
Can you post some sample data?
 
Upvote 0
I can't post a file as it's sensitive stuff, but here is an example of what the data looks like. Hope this is enough to get idea of the problem. Thanks.
Run,Date,:,,24/07/2020,,,,,,,,,,,,,,,,,,,,,,,,,,,,,,,,,,,,,,,,,,,,,,,,,,,,,,,,,,,,,,,,,,,,,,,,,,,,,,,,,,,,,,,,,,,,,,,,,Page:,,,,,,1,
,,,,,,,,,,,,,,,,,,,,,,,,WORK,CATEGORY,COUNTS,AND,PERFORMANCE,INDICATORS,FOR,PERIOD,18/07/2020,TO,24/07/2020,,,,,,,,,,,,,,,,,,,,,,,,,
,,,,,,,,,,,,,,,,,,,,,,,,,,,,,,,,,,,,,,,,,,,,,MANAGEMENT,UNIT,NUMBER,01226,,,,,,,,,,,,,,,,,,,,,,,,,,,,,,,,,,,,,,,,,,,,,,,,,,,,,,,,,,,
,WORK,CATEGORY,,,,,,,,,,,,,,,BROUGHT,,,,REGISTERED,,,TRANSFER,,,,,TRANSFER,,WITHDRAWN,,,CLEARED,,,,OUTSTANDING,,,,,,,PERFORMANCE,,,,
,,,,,,,,,,,,,,,,,,,,,,,,,,,,,FORWARD,,,,,,,,,,,,,,,,,,,,IN,,,,,,,,,,,OUT,,,,/DEFECTIVE,,,,,,,,,,,,,,,,,,,,,,,,,,,,,,,INDICATORS,,,,,
 
Upvote 0
You could try creating a custom function to replace multiple delimiters with one.

To do that in Power Query:

1 Right click inside the Query panel on the left and select New Query>Other Sources>Blank.

2 Rename the newly created query with a suitable name, e.g. ReplaceMultipleDelimiters.

3 Right click the query and selected Advanced Editor.

4 Replace what you see in the editor with the code below.

Code:
(String as text, optional Delimiter as text) as text =>

let
    delimiter = if Delimiter = null then " " else Delimiter,
    TextToList = List.Buffer(Text.Split(String, delimiter)),
    FilterList = List.Select(TextToList, each _ <> ""),
    Result = Text.Combine(FilterList, delimiter)
in
    Result
5 Click Done.

Now you have the function you can implement it by going to Add Column>Invoke Custom Function.

When you do that give the new column an appropriate name, select the column you want to apply it to and set the delimiter to whatever you want.
 
Upvote 0
That's a great solution, unfortunately I'm a little lost. The column I am using in my query is called 'Column1'. How would I add this to my applied steps. As you can guess I am very new to this.
 
Upvote 0
Goto the Add Column tab in Power Query and select Invoke Custom Function.

You should now see a dialog where you can set the New Column Name and select the Function to apply, e.g. ReplaceMultipleDelimiters.

Two new fields should now appear, in the first one you can select the column to apply the function to, e.g. Column1, and in the second set the delimiter.

1596540600627.png
 
Upvote 0
No Invoke.JPG


This is the problem I have. The Invoke Custom function is missing form my version of Power query. I suspect we have a basic version is there is such a thing
 
Upvote 0
I think I will have to contact the 'I.T' department and see why it isn't there. Thanks for all the help, very much appreciate you helping me.
 
Upvote 0
I think you should update your profile (Account Details) about Excel version, less troubles and wasted posts

anyway try in PQ Editor: Alt A CF
 
Upvote 0

Forum statistics

Threads
1,223,760
Messages
6,174,339
Members
452,555
Latest member
colc007

We've detected that you are using an adblocker.

We have a great community of people providing Excel help here, but the hosting costs are enormous. You can help keep this site running by allowing ads on MrExcel.com.
Allow Ads at MrExcel

Which adblocker are you using?

Disable AdBlock

Follow these easy steps to disable AdBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the icon in the browser’s toolbar.
2)Click on the "Pause on this site" option.
Go back

Disable AdBlock Plus

Follow these easy steps to disable AdBlock Plus

1)Click on the icon in the browser’s toolbar.
2)Click on the toggle to disable it for "mrexcel.com".
Go back

Disable uBlock Origin

Follow these easy steps to disable uBlock Origin

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back

Disable uBlock

Follow these easy steps to disable uBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back
Back
Top