Power Query: Edit Rows, not Columns

jbeam4me

New Member
Joined
Aug 18, 2016
Messages
15
Apologies in advance for my PQ ignorance as I'm fairly new to its use. I do, however, feel I've combed the internet in search for an answer to my question, have not found it, and, thus, have landed here :)

1) I "Power Query" a local unedited excel corporate-provided report and begin my edits.
2) I can remove the first two rows of "unneeded text" without issue.
3) The issue I'm having is figuring out a way to Concatenate (or another method) to get B4:D4 to display a date based on provided text values pre-populated in B3:D4.

In simpler terms: I'm trying to automate my query transformation steps so that upon "refresh", the editor leaves me with MM/YY in B4:D4 (the data I'm working with could include up to 10+ years of columns--whereas below I'm simply listing a simple example for this question).

A1:D6 table example within Power Query Editor
unneeded textnullnullnull
unneeded text nullnullnull
nullY2015Y2015Y2015
nullJanFebMar
Billed Revenue$1$1$1
Accrued Revenue$2$2$2

<tbody>
</tbody>











What I hope to achieve (after this step, I would delete the first 3 rows and then make first row as my header row within editor).
unneeded textnullnullnull
unneeded text nullnullnull
nullY2015Y2015Y2015
null01/1502/1503/15
Billed Revenue$1$1$1
Accrued Revenue$2$2$2


<tbody>
</tbody>
 

Excel Facts

Using Function Arguments with nested formulas
If writing INDEX in Func. Arguments, type MATCH(. Use the mouse to click inside MATCH in the formula bar. Dialog switches to MATCH.
The only way I know how to handle this is to transpose the data (columns become rows), then parse the dates together and then transpose back.
 
Upvote 0
So that would look something like:
Code:
let
    Source = Excel.CurrentWorkbook(){[Name="Input"]}[Content],
    Transposed = Table.Transpose(Source),
    MonthNumbers = Table.TransformColumns(Transposed,{{"Column4", each if List.PositionOf({"Jan","Feb","Mar","Apr","May","Jun","Jul","Aug","Sep","Oct","Nov","Dec"}, _) = -1 then _ else Text.PadStart(Text.From(1+List.PositionOf({"Jan","Feb","Mar","Apr","May","Jun","Jul","Aug","Sep","Oct","Nov","Dec"}, _)),2,"0")}}),
    YearsWithSlash = Table.TransformColumns(MonthNumbers,{{"Column3", each if Text.StartsWith(_,"Y") and Text.Length(_) = 5 then "/"&Text.End(_,2) else _}}),
    Merged = Table.CombineColumns(YearsWithSlash,{"Column4", "Column3"},Combiner.CombineTextByDelimiter("", QuoteStyle.None),"Merged"),
    TransposedBack = Table.Transpose(Merged)
in
    TransposedBack
 
Upvote 0

Forum statistics

Threads
1,214,907
Messages
6,122,185
Members
449,071
Latest member
cdnMech

We've detected that you are using an adblocker.

We have a great community of people providing Excel help here, but the hosting costs are enormous. You can help keep this site running by allowing ads on MrExcel.com.
Allow Ads at MrExcel

Which adblocker are you using?

Disable AdBlock

Follow these easy steps to disable AdBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the icon in the browser’s toolbar.
2)Click on the "Pause on this site" option.
Go back

Disable AdBlock Plus

Follow these easy steps to disable AdBlock Plus

1)Click on the icon in the browser’s toolbar.
2)Click on the toggle to disable it for "mrexcel.com".
Go back

Disable uBlock Origin

Follow these easy steps to disable uBlock Origin

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back

Disable uBlock

Follow these easy steps to disable uBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back
Back
Top