Skip to main content
cancel
Showing results for 
Search instead for 
Did you mean: 

Earn the coveted Fabric Analytics Engineer certification. 100% off your exam for a limited time only!

Reply
ovetteabejuela
Impactful Individual
Impactful Individual

PowerQuery Question: Renaming Header

Hi,

 

I've got a data source that is in Chinese, the headers are in Chinese but I already have the equivalent in English but how do I rename the header in Advanced Mode that

 

If <header-in-chinese_1> then <header-in-english_1>

If <header-in-chinese_2> then <header-in-english_2>

 

 

1 ACCEPTED SOLUTION

MissingField.Error would halt the input process.

 

I don't know if there is a standard approach.

My suggestion would be to create 3 queries, like:

  1. ColumnRenames with From and To column Names
  2. GetInput: getting the input and renaming the columns with MissingField.Ignore
  3. CheckInput: select all records from ColumnRenames of which the To name does not exist in GetInput (should be empty).

You may then include CheckInput in some visual as an alert.

 

Below some sample code you can copy/paste in an empty pbix file to see how t works.

 

ColumnRenames:

let
    Source = #table(type table[From = text, To = text],{{"Chinese 1", "English 1"},{"Chinese 2", "English 2"},{"Chinese 3", "English 3"}})
in
    Source

 

GetInput (I just created some data in a table with 2 columns):

let
    Source = {1..10},
    #"Converted to Table" = Table.FromList(Source, Splitter.SplitByNothing(), null, null, ExtraValues.Error),
    #"Renamed Columns" = Table.RenameColumns(#"Converted to Table",{{"Column1", "Chinese 1"}}),
    #"Added Index" = Table.AddIndexColumn(#"Renamed Columns", "Chinese 2", 0, 1),
    #"Renamed Columns1" = Table.RenameColumns(#"Added Index",Table.ToRows(ColumnRenames), MissingField.Ignore)
in
    #"Renamed Columns1"

 

CheckInput (just a oneliner, without let .. in):

Table.SelectRows(ColumnRenames, each not List.Contains(Table.ColumnNames(GetInput),[To]))
Specializing in Power Query Formula Language (M)

View solution in original post

5 REPLIES 5
ovetteabejuela
Impactful Individual
Impactful Individual

Let me change my question...

 

Do I have to evaluate if the header exists? Like what the header name has changed? How do we handle this properly?

You can add a third argument MissingField.Ignore to Table.RenameColumns, like:

 

= Table.RenameColumns(PreviousStep,{{"Chinese name", "English name"}}, MissingField.Ignore)

 

Alternatively, you can use MissingField.UseNull, then the column with the English name will be created with null values, in case the column with the Chinese name does not exist.

The default is MissingField.Error

Specializing in Power Query Formula Language (M)

That is very much helpful @MarcelBeug and thank you very much. I do have more question though...

 

If this is a regular task for someone already, would there be a way to be notified that an error has occured or a Header name has gone missing? If I use the default MissingField.Error would that halt the import process?

 

I will try it now but maybe what I wanted to know is if there is an error handling best suited for a scenario like that.

MissingField.Error would halt the input process.

 

I don't know if there is a standard approach.

My suggestion would be to create 3 queries, like:

  1. ColumnRenames with From and To column Names
  2. GetInput: getting the input and renaming the columns with MissingField.Ignore
  3. CheckInput: select all records from ColumnRenames of which the To name does not exist in GetInput (should be empty).

You may then include CheckInput in some visual as an alert.

 

Below some sample code you can copy/paste in an empty pbix file to see how t works.

 

ColumnRenames:

let
    Source = #table(type table[From = text, To = text],{{"Chinese 1", "English 1"},{"Chinese 2", "English 2"},{"Chinese 3", "English 3"}})
in
    Source

 

GetInput (I just created some data in a table with 2 columns):

let
    Source = {1..10},
    #"Converted to Table" = Table.FromList(Source, Splitter.SplitByNothing(), null, null, ExtraValues.Error),
    #"Renamed Columns" = Table.RenameColumns(#"Converted to Table",{{"Column1", "Chinese 1"}}),
    #"Added Index" = Table.AddIndexColumn(#"Renamed Columns", "Chinese 2", 0, 1),
    #"Renamed Columns1" = Table.RenameColumns(#"Added Index",Table.ToRows(ColumnRenames), MissingField.Ignore)
in
    #"Renamed Columns1"

 

CheckInput (just a oneliner, without let .. in):

Table.SelectRows(ColumnRenames, each not List.Contains(Table.ColumnNames(GetInput),[To]))
Specializing in Power Query Formula Language (M)

@MarcelBeug, I have yet to try but I can see where you're going and I already think that this is an awesome approach. I will try and get back to this thread and will flag it as a solution when everything works.

 

Thanks again for the elaborate assistance.

Helpful resources

Announcements
April AMA free

Microsoft Fabric AMA Livestream

Join us Tuesday, April 09, 9:00 – 10:00 AM PST for a live, expert-led Q&A session on all things Microsoft Fabric!

March Fabric Community Update

Fabric Community Update - March 2024

Find out what's new and trending in the Fabric Community.