Forum Discussion
KLolli
May 19, 2021Copper Contributor
Transform a table in Excel: transpose vs pivot and repeaded cells
Hello, I need help with transforming a table: from the example on the left, to the one on the right. I tried pivot column but where more dates are present for the same name, I had an error. I a...
- May 20, 2021
On reflection the following is more straightforward and less complex to understand + Columns names are fully dynamic: whatever the names of your 2 columns are in the source table this will work as long as the column containing the dates is the 2nd column
let Source = Excel.CurrentWorkbook(){[Name="Table1"]}[Content], SourceColumns = Table.ColumnNames(Source), FirstColumn = List.First(SourceColumns), GroupedRows = Table.Group(Source, FirstColumn, {"DATA", each Table.FromRows( { {Table.FirstValue(_)} & Table.Column(_, List.Last(SourceColumns)) } ), type table } ), CombinedTables = Table.Combine(GroupedRows[DATA]), DateColumns = List.Transform({1..Table.ColumnCount(CombinedTables)-1}, each "DATE " & Text.From(_) ), RenamedColumns = Table.RenameColumns(CombinedTables, List.Zip({ Table.ColumnNames(CombinedTables), {FirstColumn} & DateColumns }) ), TypedDate = Table.TransformColumnTypes(RenamedColumns, List.Transform(DateColumns, each {_, type date}) ) in TypedDate
https://1drv.ms/x/s!AsuqEFbTJNgcgaAy4BA7qsu5MHYgyQ?e=aatBxh - see BetterQuery
KLolli
May 20, 2021Copper Contributor
Hi,
Essentially I start from a table like the one on the left, 2 columns, one for names and one for dates and I want a "result table" like the one on the left.
I managed to get a table that has many rows (one for each date in column B) using Power query-pivot colunm and I applied your Unique formula to that (now will try on the original table). I managed to get it work, and it does the job, now my problem is that I don't know how to automate this.
I need tables in order to be able to update automatically the data every time I receave a new extract, that's why I was hoping there was a solution via Power query.
Essentially I start from a table like the one on the left, 2 columns, one for names and one for dates and I want a "result table" like the one on the left.
I managed to get a table that has many rows (one for each date in column B) using Power query-pivot colunm and I applied your Unique formula to that (now will try on the original table). I managed to get it work, and it does the job, now my problem is that I don't know how to automate this.
I need tables in order to be able to update automatically the data every time I receave a new extract, that's why I was hoping there was a solution via Power query.
Lorenzo
May 20, 2021Silver Contributor
On reflection the following is more straightforward and less complex to understand + Columns names are fully dynamic: whatever the names of your 2 columns are in the source table this will work as long as the column containing the dates is the 2nd column
let
Source = Excel.CurrentWorkbook(){[Name="Table1"]}[Content],
SourceColumns = Table.ColumnNames(Source),
FirstColumn = List.First(SourceColumns),
GroupedRows = Table.Group(Source, FirstColumn,
{"DATA", each Table.FromRows(
{ {Table.FirstValue(_)} & Table.Column(_, List.Last(SourceColumns)) }
), type table
}
),
CombinedTables = Table.Combine(GroupedRows[DATA]),
DateColumns = List.Transform({1..Table.ColumnCount(CombinedTables)-1}, each
"DATE " & Text.From(_)
),
RenamedColumns = Table.RenameColumns(CombinedTables,
List.Zip({
Table.ColumnNames(CombinedTables),
{FirstColumn} & DateColumns
})
),
TypedDate = Table.TransformColumnTypes(RenamedColumns,
List.Transform(DateColumns, each {_, type date})
)
in
TypedDate
https://1drv.ms/x/s!AsuqEFbTJNgcgaAy4BA7qsu5MHYgyQ?e=aatBxh - see BetterQuery
- KLolliMay 20, 2021Copper ContributorDear L z.,
Thank you so much for the time you spent to solve my problem.
I am not an expert and I will try to figure out how to apply your solution, and I'll let you know if I'll manage to do that, but in the meantime, I just want to thank you again!
KL- KLolliMay 20, 2021Copper ContributorDear L z.,
Thank you so so much! I manage to use it and it work perfectly with my data set.
Now will try to learn better what each step is/mean.
Once more, thank you! Fantastic!
KL