Get certified in Microsoft Fabric—for free! For a limited time, the Microsoft Fabric Community team will be offering free DP-600 exam vouchers. Prepare now
Hi all,
my SQL Server DBA tells me that SQL doesn't like spaces in column names, and all tables and views in that project have unsightly underscores. In Power BI, I want to replace them with blanks, but changing all the column names manually is way too time consuming and doesn't scale well if more columns are added to the table or view.
Therefore, I wrote this little piece of M code that I put at the beginning of the query, just after navigating to the view or table I want. I hope that some of you find this useful.
let
Source = Sql.Database("YourServer", "YourDatabase"),
Navigation = Source{[Schema = "YourSchema", Item = "YourTableorView"]}[Data],
// SQL Server doesn't like blanks in column names, so they come with underscores.
// We replace underscores in any column name with blanks
// list column names, turn the list into a table duplicate the name column, replace underscore with blank
// turn the table into a list of lists
ColumNames = Table.ColumnNames(Navigation),
ColumnNamesTable = Table.FromList(ColumNames, Splitter.SplitByNothing(), null, null, ExtraValues.Error),
DuplicateColumnName = Table.DuplicateColumn(ColumnNamesTable, "Column1", "Column1 - Copy"),
ReplaceCharacter = Table.ReplaceValue(DuplicateColumnName, "_", " ", Replacer.ReplaceText, {"Column1 - Copy"}),
ColumnNamesList = Table.ToRows(ReplaceCharacter),
// rename the original column names with the names from the list of lists
RenamedColumnsFromList = Table.RenameColumns(Navigation,ColumnNamesList)
in
RenamedColumnsFromList
Let me know how you get on with this.
cheers, teylyn
Solved! Go to Solution.
Table.RenameColumns(Navigation,List.Transform(Table.ColumnNames(Navigation),each {_,Text.Replace(_,"_"," ")}))
Hi @teylyn and @wdx223_Daniel ,
I've been there as well before I've discovered that the M-language has some nice functions that are not exposed through the UI. Transforming column names with a custom function is one of them:
Table.TransformColumnNames(Source, each Text.Replace(_, "_", " ") )
Imke Feldmann (The BIccountant)
If you liked my solution, please give it a thumbs up. And if I did answer your question, please mark this post as a solution. Thanks!
How to integrate M-code into your solution -- How to get your questions answered quickly -- How to provide sample data -- Check out more PBI- learning resources here -- Performance Tipps for M-queries
Hi @DAXTERONPOWERBI ,
this error usually occurs when one misses a comma or didn't apply the quotes correctly. So you might want to check your M-code.
Imke Feldmann (The BIccountant)
If you liked my solution, please give it a thumbs up. And if I did answer your question, please mark this post as a solution. Thanks!
How to integrate M-code into your solution -- How to get your questions answered quickly -- How to provide sample data -- Check out more PBI- learning resources here -- Performance Tipps for M-queries
Hi @teylyn and @wdx223_Daniel ,
I've been there as well before I've discovered that the M-language has some nice functions that are not exposed through the UI. Transforming column names with a custom function is one of them:
Table.TransformColumnNames(Source, each Text.Replace(_, "_", " ") )
Imke Feldmann (The BIccountant)
If you liked my solution, please give it a thumbs up. And if I did answer your question, please mark this post as a solution. Thanks!
How to integrate M-code into your solution -- How to get your questions answered quickly -- How to provide sample data -- Check out more PBI- learning resources here -- Performance Tipps for M-queries
@wdx223_Daniel Great to see that it can be done in one step. I find the M syntax less than intuitive when it comes to writing nested formulas.
Table.RenameColumns(Navigation,List.Transform(Table.ColumnNames(Navigation),each {_,Text.Replace(_,"_"," ")}))
Works perfect! Thanks a lot!
Note: change Navigation with the name of previous step/table name and replace with Text.Replace(_," ","_") if you want to replace space with _
Hi, this solution does not work instead it gives follwing error
Expression.SyntaxError: Token Eof expected.
I use the following to make it fit for sql:
TextLower = Table.TransformColumnNames(PreviousStepTableName, Text.Lower),
LowerDash = Table.RenameColumns( TextLower, List.Transform(Table.ColumnNames(TextLower), each {_, Text.Replace(_," ","_")}), MissingField.Ignore)
Please kindly change Navigation with the name of previous step/table name and replace with Text.Replace(_," ","_") if you want to replace space with _
Check out the October 2024 Power BI update to learn about new features.
Learn from experts, get hands-on experience, and win awesome prizes.
User | Count |
---|---|
65 | |
61 | |
21 | |
18 | |
12 |