• Skip to main content
  • Skip to header right navigation
  • Skip to site footer

My Online Training Hub

Learn Dashboards, Excel, Power BI, Power Query, Power Pivot

  • Courses
  • Pricing
    • Free Courses
    • Power BI Course
    • Excel Power Query Course
    • Power Pivot and DAX Course
    • Excel Dashboard Course
    • Excel PivotTable Course – Quick Start
    • Advanced Excel Formulas Course
    • Excel Expert Advanced Excel Training
    • Excel Tables Course
    • Excel, Word, Outlook
    • Financial Modelling Course
    • Excel PivotTable Course
    • Excel for Customer Service Professionals
    • Excel for Operations Management Course
    • Excel for Decision Making Under Uncertainty Course
    • Excel for Finance Course
    • Excel Analysis ToolPak Course
    • Multi-User Pricing
  • Resources
    • Free Downloads
    • Excel Functions Explained
    • Excel Formulas
    • Excel Add-ins
    • IF Function
      • Excel IF Statement Explained
      • Excel IF AND OR Functions
      • IF Formula Builder
    • Time & Dates in Excel
      • Excel Date & Time
      • Calculating Time in Excel
      • Excel Time Calculation Tricks
      • Excel Date and Time Formatting
    • Excel Keyboard Shortcuts
    • Excel Custom Number Format Guide
    • Pivot Tables Guide
    • VLOOKUP Guide
    • ALT Codes
    • Excel VBA & Macros
    • Excel User Forms
    • VBA String Functions
  • Members
    • Login
    • Password Reset
  • Blog
  • Excel Webinars
  • Excel Forum
    • Register as Forum Member

Dynamically expand and change column types when new records added|Power Query|Excel Forum|My Online Training Hub

You are here: Home / Dynamically expand and change column types when new records added|Power Query|Excel Forum|My Online Training Hub
Avatar
sp_LogInOut Log In sp_Registration Register
sp_Search Search
Advanced Search|Last Search Results
Search
Forum Scope




Match



Forum Options



Minimum search word length is 3 characters - maximum search word length is 84 characters
sp_Search Search
sp_RankInfo
Lost password?
sp_CrumbsHome HomeExcel ForumPower QueryDynamically expand and change colum…
sp_PrintTopic sp_TopicIcon
Dynamically expand and change column types when new records added
Avatar
Chris Yap
Member
Members
Level 0
Forum Posts: 162
Member Since:
August 21, 2019
sp_UserOfflineSmall Offline
1
September 16, 2020 - 12:22 pm
sp_Permalink sp_Print

Hi PQ Guru

for the attached example,  basically new id and date will be added overtimes,  notice that newly added record (that is new to the transpose table,  for e.g Column 5) will not be automatically appeared in the transformed table (require to manually go to expanded custom to check it)

Previously I had also figured out mass rename of Column1, Column2, Column3 to Date1, Date2, Date3.....

= Table.TransformColumnNames(#"Expanded Custom", each Text.Replace(_ ,"Column","Date"))

Is there a direct M code to do the same for Changing all the column types to Date

 

and also how to avoid manually checking all the newly added column in the expanded custom to update the transposed table

 

Thank you Sir /Madam

sp_AnswersTopicSeeAnswer See Answer
Avatar
Philip Treacy
Admin
Level 10
Forum Posts: 1518
Member Since:
October 5, 2010
sp_UserOfflineSmall Offline
2
September 16, 2020 - 1:41 pm
sp_Permalink sp_Print

Hi Chris,

the output table in the workbook isn't in a tabular format so it's not in a layout that can easily be used with pivot tables etc.

The input table is actually the layout you want,no need to transform it.

What exactly are you trying to do?  What analysis/report are you trying to prepare from the source table?

Regards

Phil

Avatar
Chris Yap
Member
Members
Level 0
Forum Posts: 162
Member Since:
August 21, 2019
sp_UserOfflineSmall Offline
3
September 16, 2020 - 4:35 pm
sp_Permalink sp_Print

Hi Philip,

my user wanted to view in a pivot table format for dates,  that is header with Date1, Date2..............

How about mass changing of all the columns to type date,  can this be done using one M code,  and also the automatic check of Column that are beyond,  for this example row 9 for May,  which is the fifth column,  we need to got to the expanded custom to check it,   is there a M code that can automate it

so no matter how users append to the tabular source table,   he only need to refresh all to update the power query cross table

 

Thank you !

Avatar
Philip Treacy
Admin
Level 10
Forum Posts: 1518
Member Since:
October 5, 2010
sp_UserOfflineSmall Offline
4
September 17, 2020 - 10:15 am
sp_Permalink sp_Print

Hi Chris,

It will be much easier, and new rows added to your source table will be automatically included in the final report, if you create a pivot table direct from the source and don't go through PQ.  You'll just need to add some kind of index to each entry.

In the attached file I've added this ID column and created a PT on sheet MOTH.

Regards

Phil

Avatar
Chris Yap
Member
Members
Level 0
Forum Posts: 162
Member Since:
August 21, 2019
sp_UserOfflineSmall Offline
5
September 17, 2020 - 5:03 pm
sp_Permalink sp_Print

Hi Philip,  thanks for your response,  I know Pivot table can do the job but however to figure out why the expanded cannot be automated,  sometimes we only want one solution,  i.e.  all in Power Query

 

Thank you !!

Avatar
Catalin Bombea
Iasi, Romania
Admin
Level 10
Forum Posts: 1810
Member Since:
November 8, 2013
sp_UserOfflineSmall Offline
6
September 18, 2020 - 5:00 pm
sp_Permalink sp_Print sp_EditHistory

Hi Chris,

You can use an iterative function to loop through all columns.

When you change a column format, this is what PQ generates: = Table.TransformColumnTypes(Source,{{"Date2", type date}})

What you need is to replace the static "Date2" with a variable inside the loop.

let
Source = Excel.CurrentWorkbook(){[Name="Table1"]}[Content],
ChangedType = List.Accumulate(Table.ColumnNames(Source),Source,(state,HeaderItem)=>if Text.Contains(HeaderItem,"Date") =true then Table.TransformColumnTypes(state,{{HeaderItem, type date}}) else state)
in
ChangedType

List.Accumulate will loop through all items from this list: Table.ColumnNames(Source) (which is the list of all column names in Source table)

The first argument of List.Accumulate can be a list only.

For example, You can create a loop from 1 to 10 (similar to VBA: For i=1 to 10) with List.Accumulate:
List.Accumulate({1..10}, .......

In our case, the loop through Table.ColumnNames(Source)  translates to:
For Each HeaderItem in Table.ColumnNames(Source) 

if Text.Contains(HeaderItem,"Date") =true then Table.TransformColumnTypes(state,{{HeaderItem, type date}}) else state

Next HeaderItem

Source is the initial seed, in this case the seed is a table.
At each iteration, the seed will change the state based on the function used: if the HeaderItem contains the text "Date", that column will be transformed to date format.

Avatar
Chris Yap
Member
Members
Level 0
Forum Posts: 162
Member Since:
August 21, 2019
sp_UserOfflineSmall Offline
7
September 19, 2020 - 2:52 pm
sp_Permalink sp_Print

Hi Catalin

however for my case,  I require to find a solution to automatically insert "Column4", "Column5" whenever the source file append new data,  instead of double click on Expanded Custom to physically check it

let
Source = Excel.CurrentWorkbook(){[Name="Table1"]}[Content],
#"Changed Type" = Table.TransformColumnTypes(Source,{{"DOA", type date}}),
#"Grouped Rows" = Table.Group(#"Changed Type", {"Sr."}, {{"Grouped", each _, type table [#"Sr."=number, DOA=nullable date]}}),
#"Added Custom" = Table.AddColumn(#"Grouped Rows", "Custom", each Table.Transpose(Table.SelectColumns([Grouped], "DOA"))),
#"Expanded Custom" = Table.ExpandTableColumn(#"Added Custom", "Custom", {"Column1", "Column2", "Column3"}, {"Column1", "Column2", "Column3"}),
#"Removed Columns" = Table.RemoveColumns(#"Expanded Custom",{"Grouped"}),
#"Renamed Columns" = Table.RenameColumns(#"Removed Columns",{{"Column1", "DOA Date1"}, {"Column2", "DOA Date2"}, {"Column3", "DOA Date3"}}),
#"Changed Type1" = Table.TransformColumnNames(#"Renamed Columns", each Text.Replace(_, "Column", "DOA Date")),
#"Changed Type2" = Table.TransformColumnTypes(#"Changed Type1",{{"DOA Date1", type date}, {"DOA Date2", type date}, {"DOA Date3", type date}})
in
#"Changed Type2"

 

Is it the same method that you recommended ?

 

Thank you !

Avatar
Catalin Bombea
Iasi, Romania
Admin
Level 10
Forum Posts: 1810
Member Since:
November 8, 2013
sp_UserOfflineSmall Offline
8
September 19, 2020 - 3:47 pm
sp_Permalink sp_Print

I thought it's obvious that what I provided is for formatting all columns.

You don't have to go manually and expand the new columns, that's what Table.ColumnNames does.

Instead of {"Column1", "Column2", "Column3"}, simply READ the existing column names dynamically from the previous step:

Table.ColumnNames(#"Added Custom")

Avatar
Chris Yap
Member
Members
Level 0
Forum Posts: 162
Member Since:
August 21, 2019
sp_UserOfflineSmall Offline
9
September 19, 2020 - 4:58 pm
sp_Permalink sp_Print

Sorry Catalin

After replacing it 

= Table.ExpandTableColumn(#"Added Custom", "Custom", {Table.ColumnNames(#"Added Custom")}, {Table.ColumnNames(#"Added Custom")})

got error

Expression.Error: We cannot convert a value of type List to type Text.
Details:
Value=[List]
Type=[Type]
Avatar
Catalin Bombea
Iasi, Romania
Admin
Level 10
Forum Posts: 1810
Member Since:
November 8, 2013
sp_UserOfflineSmall Offline
10
September 19, 2020 - 5:49 pm
sp_Permalink sp_Print sp_EditHistory

Instead of {"Column1", "Column2", "Column3"}, simply READ the existing column names dynamically from the previous step:

Table.ColumnNames(#"Added Custom")

 

You was supposed to replace:
{"Column1", "Column2", "Column3"}

with

Table.ColumnNames(#"Added Custom")

 

NOT with:

{Table.ColumnNames(#"Added Custom")}

 

Remove the curly brackets, will work.

Avatar
Catalin Bombea
Iasi, Romania
Admin
Level 10
Forum Posts: 1810
Member Since:
November 8, 2013
sp_UserOfflineSmall Offline
11
September 19, 2020 - 5:57 pm
sp_Permalink sp_Print sp_EditHistory

Looked into your file, and you have multiple tables in the Custom column.

To get all headers (on some rows there may be different headers), you have to combine them first.

Use:

Table.ColumnNames(Table.Combine(#"Added Custom"[Custom]))

The result of Table.ColumnNames function is a list, that's why you don't need curly brackets.

This will provide a list of all headers from all tables in Custom column, even if the tables column names are different in each row.

sp_AnswersTopicAnswer
Answers Post
Avatar
Chris Yap
Member
Members
Level 0
Forum Posts: 162
Member Since:
August 21, 2019
sp_UserOfflineSmall Offline
12
September 19, 2020 - 10:26 pm
sp_Permalink sp_Print

Hi Catalin Sir,

Finally with your tips and  guidance,  managed to code it

Thank you for your patience with me

Cheers !!!!

Avatar
Catalin Bombea
Iasi, Romania
Admin
Level 10
Forum Posts: 1810
Member Since:
November 8, 2013
sp_UserOfflineSmall Offline
13
September 20, 2020 - 1:03 am
sp_Permalink sp_Print

Glad to hear you managed to make it work.

Best,

Catalin

sp_Feed
Go to top
Forum Timezone: Australia/Brisbane
Most Users Ever Online: 245
Currently Online: Kim Knox, Bhuwan Devkota
Guest(s) 8
Currently Browsing this Page:
1 Guest(s)
Top Posters:
SunnyKow: 1432
Anders Sehlstedt: 871
Purfleet: 412
Frans Visser: 346
David_Ng: 306
lea cohen: 219
Jessica Stewart: 204
A.Maurizio: 202
Aye Mu: 201
jaryszek: 183
Newest Members:
Bhuwan Devkota
Kathryn Patton
Maria Conatser
Jefferson Granemann
Glen Coulthard
Nikki Fox
Rachele Dickie
Raj Mattoo
Mark Luke
terimeri dooriyan
Forum Stats:
Groups: 3
Forums: 24
Topics: 6221
Posts: 27285

 

Member Stats:
Guest Posters: 49
Members: 31909
Moderators: 3
Admins: 4
Administrators: Mynda Treacy, Philip Treacy, Catalin Bombea, FT
Moderators: MOTH Support, Velouria, Riny van Eekelen
© Simple:Press —sp_Information

Sidebar

Blog Categories

  • Excel
  • Excel Charts
  • Excel Dashboard
  • Excel Formulas
  • Excel PivotTables
  • Excel Shortcuts
  • Excel VBA
  • General Tips
  • Online Training
  • Outlook
  • Power Apps
  • Power Automate
  • Power BI
  • Power Pivot
  • Power Query
microsoft mvp logo
trustpilot excellent rating
Secured by Sucuri Badge
MyOnlineTrainingHub on YouTube Mynda Treacy on Linked In Mynda Treacy on Instagram Mynda Treacy on Twitter Mynda Treacy on Pinterest MyOnlineTrainingHub on Facebook
 

Company

  • About My Online Training Hub
  • Disclosure Statement
  • Frequently Asked Questions
  • Guarantee
  • Privacy Policy
  • Terms & Conditions
  • Testimonials
  • Become an Affiliate

Support

  • Contact
  • Forum
  • Helpdesk - For Technical Issues

Copyright © 2023 · My Online Training Hub · All Rights Reserved. Microsoft and the Microsoft Office logo are trademarks or registered trademarks of Microsoft Corporation in the United States and/or other countries. Product names, logos, brands, and other trademarks featured or referred to within this website are the property of their respective trademark holders.