Hi Mynda
Please can you assist. Look at my dataset. There are three sheets. The tabular data and the actual two results I need.
I would like to transpose the tabular data to get to the two results including Index Numbers. I tried it both the natural way in Excel and with PQ but do not get the desired results.
I would really appreciate if you could assist – not sure if I need VBA but I will rather settle for PQ.
i am sure there will be a much nicer PQ solution, but attached is a VBA one.
It will need finishing off but seems to capture the main requirements
Hi Amien,
It's not identical to your examples, but it's close. Hope it helps.
Mynda
Hi Mynda and Purfleet. Many thanks for your solutions.
Mynda's Solution:
I am running Excel 2016 and hit some issue trying to open the queries to enable me to follow the solution. I want to rebuild the solution as I have many more records to transpose in my master copy. My dataset with the three records was just a sample. I am not sure how to overcome this issue with Excel 2016.
Purfleet's Solution:
These two solutions will work but I am trying to understand the code and what it is doing in order to make the adjustments for it to run 98 records (99 rows incl. the header row) and another 23 records (24 rows incl. the header row with different column headings which I can adjust myself). I used F8 to step into each line of code and tried to change it to run the 98 records but to no avail. I actually copied and pasted the original 98 records in my "Result1" in the workbook you sent back with the code but like I said it does not work therefore I did not bother to run the 23 records.
Is it possible for you to change and sent me the code for "down" and "right" for me to run the 98 records first and then the 23 records?
Not sure why you can't open the file in Excel 2016. There's nothing special in there as far as I recall. Here are the queries:
This is the transposed data query:
let Source = Excel.CurrentWorkbook(){[Name="Table2"]}[Content], #"Changed Type" = Table.TransformColumnTypes(Source,{{"Column1", type text}, {"Column2", type text}, {"Column3", type any}, {"Column4", type any}, {"Column5", type any}, {"Column6", type text}, {"Column7", type text}, {"Column8", type text}, {"Column9", type text}, {"Column10", type text}, {"Column11", type any}, {"Column12", type text}, {"Column13", type text}, {"Column14", type text}}), #"Added Index" = Table.AddIndexColumn(#"Changed Type", "Index", 0, 1, Int64.Type), #"Reordered Columns" = Table.ReorderColumns(#"Added Index",{"Index", "Column1", "Column2", "Column3", "Column4", "Column5", "Column6", "Column7", "Column8", "Column9", "Column10", "Column11", "Column12", "Column13", "Column14"}), #"Transposed Table" = Table.Transpose(#"Reordered Columns"), #"Replaced Value" = Table.ReplaceValue(#"Transposed Table",0,"Index",Replacer.ReplaceValue,{"Column1"}) in #"Replaced Value"
This is the stacked data query:
let Source = Excel.CurrentWorkbook(){[Name="Table2"]}[Content], #"Added Index" = Table.AddIndexColumn(Source, "Index", 0, 1, Int64.Type), #"Reordered Columns1" = Table.ReorderColumns(#"Added Index",{"Index", "Column1", "Column2", "Column3", "Column4", "Column5", "Column6", "Column7", "Column8", "Column9", "Column10", "Column11", "Column12", "Column13", "Column14"}), #"Transposed Table" = Table.Transpose(#"Reordered Columns1"), #"Added Index2" = Table.AddIndexColumn(#"Transposed Table", "Index", 1, 1, Int64.Type), #"Replaced Value" = Table.ReplaceValue(#"Added Index2",0,"Record",Replacer.ReplaceValue,{"Column1"}), #"Merged Columns" = Table.CombineColumns(Table.TransformColumnTypes(#"Replaced Value", {{"Column2", type text}, {"Column3", type text}, {"Column4", type text}}, "en-AU"),{"Column2", "Column3", "Column4"},Combiner.CombineTextByDelimiter(";", QuoteStyle.None),"Details"), #"Merged Columns1" = Table.CombineColumns(Table.TransformColumnTypes(#"Merged Columns", {{"Index", type text}}, "en-AU"),{"Column1", "Index"},Combiner.CombineTextByDelimiter(";", QuoteStyle.None),"Labels"), #"Split Column by Delimiter" = Table.ExpandListColumn(Table.TransformColumns(#"Merged Columns1", {{"Details", Splitter.SplitTextByDelimiter(";", QuoteStyle.Csv), let itemType = (type nullable text) meta [Serialized.Text = true] in type {itemType}}}), "Details"), #"Split Column by Delimiter1" = Table.SplitColumn(#"Split Column by Delimiter", "Labels", Splitter.SplitTextByDelimiter(";", QuoteStyle.Csv), {"Labels.1", "Labels.2"}), #"Changed Type" = Table.TransformColumnTypes(#"Split Column by Delimiter1",{{"Details", type text}, {"Labels.1", type text}, {"Labels.2", Int64.Type}}), #"Added Index1" = Table.AddIndexColumn(#"Changed Type", "Index", 0, 1, Int64.Type), #"Calculated Modulo" = Table.TransformColumns(#"Added Index1", {{"Index", each Number.Mod(_, 3), type number}}), #"Reordered Columns" = Table.ReorderColumns(#"Calculated Modulo",{"Labels.1", "Details", "Labels.2", "Index"}), #"Sorted Rows" = Table.Sort(#"Reordered Columns",{{"Index", Order.Ascending}, {"Labels.2", Order.Ascending}}), #"Removed Columns" = Table.RemoveColumns(#"Sorted Rows",{"Labels.2", "Index"}), #"Renamed Columns" = Table.RenameColumns(#"Removed Columns",{{"Labels.1", "Labels"}}) in #"Renamed Columns"
Purfleet
Not to worry. I finally got it right to run more records than what is in my sample file. Great stuff! Once again, thanks and much appreciated. The code is perfect, some of us preferred the "down" results and others the "right" therefore I am glad we have both.
Mynda
Once again, thanks to you too for the PQ solution. However, I could only access the "Transposed" query upto the "Change Type" step and all the other steps show error expressions. With the "Stacked" query, I can only access the Source step and nothing else. I then tried to recreate the queries by starting with the Transposed query. I mirrored your table2 format and created the Transposed query. I opened the Advanced Editor and deleted the existing code in there then I copied and pasted your code for the Transposed query, still got the yellow error expression. I aborted.
When I open your document and I double click the "Transposed" query the system prompts: "Compatibility Warning - The queries in this workbook might be incompatible with your current version of Excel. These queries were authored with a newer version of Excel or Power Query and might not work in your current version."
Maybe my Excel version as stated in my previous reply - not sure though.
That's a shame. There must be a function in my code that you don't have. No idea which one though, sorry.
Hi Amien
Please see whether you can access to my PQ solution
Result1
let
Source = Excel.CurrentWorkbook(){[Name="Table1"]}[Content],
#"Added Index" = Table.AddIndexColumn(Source, "Index", 1, 1, Int64.Type),
#"Reordered Columns1" = Table.ReorderColumns(#"Added Index",{"Index", "Name", "Surname", "Award Value", "Value", "Approval", "Reference Number", "Commencement Date", "Expiry Date", "Account", "Title", "Number", "Author (1)", "Author (2)", "Author (3)"}),
#"Demoted Headers" = Table.DemoteHeaders(#"Reordered Columns1"),
#"Transposed Table" = Table.Transpose(#"Demoted Headers"),
#"Unpivoted Other Columns" = Table.UnpivotOtherColumns(#"Transposed Table", {"Column1"}, "Attribute", "Value"),
#"Grouped Rows" = Table.Group(#"Unpivoted Other Columns", {"Attribute"}, {{"Grouped", each _, type table [Column1=text, Attribute=text, Value=any]}}),
#"Expanded Grouped" = Table.ExpandTableColumn(#"Grouped Rows", "Grouped", {"Column1", "Value"}, {"Column1", "Value"}),
#"Removed Columns" = Table.RemoveColumns(#"Expanded Grouped",{"Attribute"}),
#"Merged Columns" = Table.CombineColumns(Table.TransformColumnTypes(#"Removed Columns", {{"Value", type text}}, "en-SG"),{"Column1", "Value"},Combiner.CombineTextByDelimiter(";", QuoteStyle.None),"Merged"),
#"Added Custom" = Table.AddColumn(#"Merged Columns", "Custom", each if Text.Contains([Merged],"Index") then Text.AfterDelimiter([Merged],";")&";"&Text.BeforeDelimiter([Merged],";") else [Merged]),
#"Removed Columns1" = Table.RemoveColumns(#"Added Custom",{"Merged"}),
#"Split Column by Delimiter" = Table.SplitColumn(#"Removed Columns1", "Custom", Splitter.SplitTextByDelimiter(";", QuoteStyle.Csv), {"Custom.1", "Custom.2"}),
#"Changed Type" = Table.TransformColumnTypes(#"Split Column by Delimiter",{{"Custom.1", type text}, {"Custom.2", type text}}),
#"Replaced Value" = Table.ReplaceValue(#"Changed Type","Index","",Replacer.ReplaceText,{"Custom.2"}),
#"Renamed Columns" = Table.RenameColumns(#"Replaced Value",{{"Custom.1", "Header"}, {"Custom.2", "Values"}})
in
#"Renamed Columns"
Result2
let
Source = Excel.CurrentWorkbook(){[Name="Table1"]}[Content],
#"Added Index" = Table.AddIndexColumn(Source, "Index", 1, 1, Int64.Type),
#"Reordered Columns1" = Table.ReorderColumns(#"Added Index",{"Index", "Name", "Surname", "Award Value", "Value", "Approval", "Reference Number", "Commencement Date", "Expiry Date", "Account", "Title", "Number", "Author (1)", "Author (2)", "Author (3)"}),
#"Demoted Headers" = Table.DemoteHeaders(#"Reordered Columns1"),
#"Transposed Table" = Table.Transpose(#"Demoted Headers"),
#"Replaced Value" = Table.ReplaceValue(#"Transposed Table","Index","Record",Replacer.ReplaceText,{"Column1"}),
#"Promoted Headers" = Table.PromoteHeaders(#"Replaced Value", [PromoteAllScalars=true]),
#"Changed Type" = Table.TransformColumnTypes(#"Promoted Headers",{{"Record", type text}, {"1", type any}, {"2", type any}, {"3", type any}})
in
#"Changed Type"
FWIW, the syntax to Table.AddIndexColumn changed to add a new fifth parameter (the columnType), which is why Mynda's version doesn't work in 2016.
Mynda:
Thanks for all the efforts to assist me. Velouria is correct. Before I saw his post I picked up the errors (yellow screens) actually start with the "Index" steps so I basically opened the "Transposed" Query and overwritten the existing step to add a new "Index" step so finally I got that "Transposed" Query to work in your initial workbook. However, with the "Stacked" Query I first tried copying and pasting your latest round of steps but to no avail. I then tried to go through the steps, step-by-step" and noticed the error appears with the "Index" steps again but I just can't get this one right.
Velouria: Thanks to you too for spotting the problem and helping out.
Mynda, this is why this is the best platform. I just love you guys, you are awesome and it just shows there are many ways to overcome a problem. For now, I will settle with Purfleet's VBA Code as it helps when the number of column headers and rows/records changes.
I am happy. I think we can close this one for now.