Forum

Dynamically expand ...
 
Notifications
Clear all

Dynamically expand and change column types when new records added

13 Posts
3 Users
0 Reactions
332 Views
(@bluesky63)
Posts: 162
Estimable Member
Topic starter
 

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

 
Posted : 16/09/2020 10:22 pm
Philip Treacy
(@philipt)
Posts: 1629
Member Admin
 

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

 
Posted : 16/09/2020 11:41 pm
(@bluesky63)
Posts: 162
Estimable Member
Topic starter
 

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 !

 
Posted : 17/09/2020 2:35 am
Philip Treacy
(@philipt)
Posts: 1629
Member Admin
 

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

 
Posted : 17/09/2020 8:15 pm
(@bluesky63)
Posts: 162
Estimable Member
Topic starter
 

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 !!

 
Posted : 18/09/2020 3:03 am
(@catalinb)
Posts: 1937
Member Admin
 

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.

 
Posted : 19/09/2020 3:00 am
(@bluesky63)
Posts: 162
Estimable Member
Topic starter
 

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 !

 
Posted : 20/09/2020 12:52 am
(@catalinb)
Posts: 1937
Member Admin
 

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")

 
Posted : 20/09/2020 1:47 am
(@bluesky63)
Posts: 162
Estimable Member
Topic starter
 

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=

    Type=[Type]
 
Posted : 20/09/2020 2:58 am
(@catalinb)
Posts: 1937
Member Admin
 

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.

 
Posted : 20/09/2020 3:49 am
(@catalinb)
Posts: 1937
Member Admin
 

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.

 
Posted : 20/09/2020 3:57 am
(@bluesky63)
Posts: 162
Estimable Member
Topic starter
 

Hi Catalin Sir,

Finally with your tips and  guidance,  managed to code it

Thank you for your patience with me

Cheers !!!!

 
Posted : 20/09/2020 8:26 am
(@catalinb)
Posts: 1937
Member Admin
 

Glad to hear you managed to make it work.

Best,

Catalin

 
Posted : 20/09/2020 11:03 am
Share: