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

The Power BI Data Visualization World Championships is back! Get ahead of the game and start preparing now! Learn more

Reply
smpa01
Super User
Super User

Dynamically create column if a particular column does not exist within the data

Hi,

 

I receive numerous excel files each month which I need to consolidate. I use Excel.Workbook to do that.

 

However, a particular column "Semi Annual" may or may not present in those files.

 

Is there a way to dynamically create a column if that particular column is absent from that particular table. Is is possible to acheive in PBI?

 

Raw Data and Desired Result- https://drive.google.com/open?id=1iwTNyxrHwHDiRs6zw0UpvLvnSKfVQm7f

 

 

Thank you in advance.

Did I answer your question? Mark my post as a solution!
Proud to be a Super User!
My custom visualization projects
Plotting Live Sound: Viz1
Beautiful News:Viz1, Viz2, Viz3
Visual Capitalist: Working Hrs
1 ACCEPTED SOLUTION

Hi,

 

This code works fine for me.  I saved all 3 files on a desktop folder named Data.  From all 3 files i deleted the first row (where the file name was mentioend).  Here's the M query

 

let
    Source = Folder.Files("C:\Users\Ashish\Desktop\Data"),
    #"Removed Other Columns" = Table.SelectColumns(Source,{"Content"}),
    #"Added Custom" = Table.AddColumn(#"Removed Other Columns", "Custom", each Excel.Workbook([Content])),
    #"Removed Columns" = Table.RemoveColumns(#"Added Custom",{"Content"}),
    #"Expanded Custom" = Table.ExpandTableColumn(#"Removed Columns", "Custom", {"Name", "Data", "Item", "Kind", "Hidden"}, {"Name", "Data", "Item", "Kind", "Hidden"}),
    #"Removed Other Columns1" = Table.SelectColumns(#"Expanded Custom",{"Data"}),
    #"Added Custom1" = Table.AddColumn(#"Removed Other Columns1", "Custom", each Table.PromoteHeaders([Data])),
    #"Removed Columns1" = Table.RemoveColumns(#"Added Custom1",{"Data"}),
    #"Expanded Custom1" = Table.ExpandTableColumn(#"Removed Columns1", "Custom", {"Month #", "ID", "Annual", "Quarterly", "Monthly", "Total", "Semi Annual "}, {"Month #", "ID", "Annual", "Quarterly", "Monthly", "Total", "Semi Annual "}),
    #"Reordered Columns" = Table.ReorderColumns(#"Expanded Custom1",{"Month #", "ID", "Annual", "Semi Annual ", "Quarterly", "Monthly", "Total"}),
    #"Changed Type" = Table.TransformColumnTypes(#"Reordered Columns",{{"Month #", Int64.Type}, {"ID", Int64.Type}, {"Annual", Int64.Type}, {"Semi Annual ", Int64.Type}, {"Quarterly", Int64.Type}, {"Monthly", Int64.Type}, {"Total", Int64.Type}})
in
    #"Changed Type"

 

The result is

 

Untitled.png


Regards,
Ashish Mathur
http://www.ashishmathur.com
https://www.linkedin.com/in/excelenthusiasts/

View solution in original post

8 REPLIES 8
Ashish_Mathur
Super User
Super User

Hi,

 

What error do you face when you use that technique for appending data from multiple files/sheets?


Regards,
Ashish Mathur
http://www.ashishmathur.com
https://www.linkedin.com/in/excelenthusiasts/

Hi Ashish,

 

I could not achieve what I was looking for. Sorry My raw data earlier was incorrect.

 

Raw Data -https://drive.google.com/open?id=1MCHZZVEvdKU5PyoFEcKqKCfSrJ9tUnNN

 

This is what I have tried by appending

 

1.xlsx
let
    Source = Folder.Files("C:\Users\Desktop\Test"),
    #"Added Custom" = Table.AddColumn(Source, "Custom", each Excel.Workbook([Content])),
    #"Filtered Rows" = Table.SelectRows(#"Added Custom", each ([Name] = "1.xlsx")),
    #"Removed Other Columns1" = Table.SelectColumns(#"Filtered Rows",{"Custom"}),
    #"Removed Other Columns" = Table.SelectColumns(#"Removed Other Columns1",{"Custom"}),
    #"Expanded Custom" = Table.ExpandTableColumn(#"Removed Other Columns", "Custom", {"Data"}, {"Data"}),
    #"Expanded Data" = Table.ExpandTableColumn(#"Expanded Custom", "Data", {"Column1", "Column2", "Column3", "Column4", "Column5", "Column6"}, {"Column1", "Column2", "Column3", "Column4", "Column5", "Column6"})
in
    #"Expanded Data"
2.xlsx

let
    Source = Folder.Files("C:\Users\Desktop\Test"),
    #"Added Custom" = Table.AddColumn(Source, "Custom", each Excel.Workbook([Content])),
    #"Filtered Rows" = Table.SelectRows(#"Added Custom", each ([Name] = "2.xlsx")),
    #"Removed Other Columns1" = Table.SelectColumns(#"Filtered Rows",{"Custom"}),
    #"Removed Other Columns" = Table.SelectColumns(#"Removed Other Columns1",{"Custom"}),
    #"Expanded Custom" = Table.ExpandTableColumn(#"Removed Other Columns", "Custom", {"Data"}, {"Data"}),
    #"Expanded Data" = Table.ExpandTableColumn(#"Expanded Custom", "Data", {"Column1", "Column2", "Column3", "Column4", "Column5", "Column6"}, {"Column1", "Column2", "Column3", "Column4", "Column5", "Column6"})
in
    #"Expanded Data"
3.xlsx

let
    Source = Folder.Files("C:\Users\Desktop\Test"),
    #"Added Custom" = Table.AddColumn(Source, "Custom", each Excel.Workbook([Content])),
    #"Filtered Rows" = Table.SelectRows(#"Added Custom", each ([Name] = "3.xlsx")),
    #"Removed Other Columns1" = Table.SelectColumns(#"Filtered Rows",{"Custom"}),
    #"Removed Other Columns" = Table.SelectColumns(#"Removed Other Columns1",{"Custom"}),
    #"Expanded Custom" = Table.ExpandTableColumn(#"Removed Other Columns", "Custom", {"Data"}, {"Data"}),
    #"Expanded Data" = Table.ExpandTableColumn(#"Expanded Custom", "Data", {"Column1", "Column2", "Column3", "Column4", "Column5", "Column6"}, {"Column1", "Column2", "Column3", "Column4", "Column5", "Column6"})
in
    #"Expanded Data"
Append

let
    Source = Table.Combine({#"Test (2)", #"Test (3)", #"Test (4)"})
in
    Source
Did I answer your question? Mark my post as a solution!
Proud to be a Super User!
My custom visualization projects
Plotting Live Sound: Viz1
Beautiful News:Viz1, Viz2, Viz3
Visual Capitalist: Working Hrs

Hi,

 

This code works fine for me.  I saved all 3 files on a desktop folder named Data.  From all 3 files i deleted the first row (where the file name was mentioend).  Here's the M query

 

let
    Source = Folder.Files("C:\Users\Ashish\Desktop\Data"),
    #"Removed Other Columns" = Table.SelectColumns(Source,{"Content"}),
    #"Added Custom" = Table.AddColumn(#"Removed Other Columns", "Custom", each Excel.Workbook([Content])),
    #"Removed Columns" = Table.RemoveColumns(#"Added Custom",{"Content"}),
    #"Expanded Custom" = Table.ExpandTableColumn(#"Removed Columns", "Custom", {"Name", "Data", "Item", "Kind", "Hidden"}, {"Name", "Data", "Item", "Kind", "Hidden"}),
    #"Removed Other Columns1" = Table.SelectColumns(#"Expanded Custom",{"Data"}),
    #"Added Custom1" = Table.AddColumn(#"Removed Other Columns1", "Custom", each Table.PromoteHeaders([Data])),
    #"Removed Columns1" = Table.RemoveColumns(#"Added Custom1",{"Data"}),
    #"Expanded Custom1" = Table.ExpandTableColumn(#"Removed Columns1", "Custom", {"Month #", "ID", "Annual", "Quarterly", "Monthly", "Total", "Semi Annual "}, {"Month #", "ID", "Annual", "Quarterly", "Monthly", "Total", "Semi Annual "}),
    #"Reordered Columns" = Table.ReorderColumns(#"Expanded Custom1",{"Month #", "ID", "Annual", "Semi Annual ", "Quarterly", "Monthly", "Total"}),
    #"Changed Type" = Table.TransformColumnTypes(#"Reordered Columns",{{"Month #", Int64.Type}, {"ID", Int64.Type}, {"Annual", Int64.Type}, {"Semi Annual ", Int64.Type}, {"Quarterly", Int64.Type}, {"Monthly", Int64.Type}, {"Total", Int64.Type}})
in
    #"Changed Type"

 

The result is

 

Untitled.png


Regards,
Ashish Mathur
http://www.ashishmathur.com
https://www.linkedin.com/in/excelenthusiasts/

Thanks @Ashish_Mathur it worked for me. I did not know how to append while consolidating files at the same time. I learnt that today.

Did I answer your question? Mark my post as a solution!
Proud to be a Super User!
My custom visualization projects
Plotting Live Sound: Viz1
Beautiful News:Viz1, Viz2, Viz3
Visual Capitalist: Working Hrs

You are welcome.


Regards,
Ashish Mathur
http://www.ashishmathur.com
https://www.linkedin.com/in/excelenthusiasts/

A follow-up question for @Ashish_Mathur. You mentioned earlier "From all 3 files i deleted the first row (where the file name was mentioend)." - Can this part be automated? Is there a PBI code which can insturct the query to delete the first row by any chance rather than having me to do it manually?

 

The reason why I am asking you this as I receive 100-120 Raw files at once and I need to create the output. If there is a smart way of avoiding the manual work involved in deleting the first row from each of them, I would do it.

 

Thank you in advance.

Did I answer your question? Mark my post as a solution!
Proud to be a Super User!
My custom visualization projects
Plotting Live Sound: Viz1
Beautiful News:Viz1, Viz2, Viz3
Visual Capitalist: Working Hrs

Hi,

 

I tried but i could not solve it with that row remaining.


Regards,
Ashish Mathur
http://www.ashishmathur.com
https://www.linkedin.com/in/excelenthusiasts/

Thanks for trying and thanks for your time.

Did I answer your question? Mark my post as a solution!
Proud to be a Super User!
My custom visualization projects
Plotting Live Sound: Viz1
Beautiful News:Viz1, Viz2, Viz3
Visual Capitalist: Working Hrs

Helpful resources

Announcements
Power BI DataViz World Championships

Power BI Dataviz World Championships

The Power BI Data Visualization World Championships is back! Get ahead of the game and start preparing now!

December 2025 Power BI Update Carousel

Power BI Monthly Update - December 2025

Check out the December 2025 Power BI Holiday Recap!

FabCon Atlanta 2026 carousel

FabCon Atlanta 2026

Join us at FabCon Atlanta, March 16-20, for the ultimate Fabric, Power BI, AI and SQL community-led event. Save $200 with code FABCOMM.