Power Query Transforming Column with Actual and Budget Amounts

legalhustler

Well-known Member
Joined
Jun 5, 2014
Messages
1,160
Office Version
  1. 365
Platform
  1. Windows
I have the following three columns of data in Power Query that looks like this:

Category...……….Month...……..............Amount

Sales...…………….Jan Actual...……………......$100
Sales...…………….Jan Budget...................$90
Sales................Feb Actual....................$200
Sales................Feb Budget..................$250
Legal.......…………Jan Actual...……………......$500
Legal.......…………Jan Budget...................$400
Salaries...…………Feb Actual...……………......$550
Salaries...…………Feb Budget...................$450
Marketing...………Jan Actual...……………......$45
Marketing...………Jan Budget...................$40
Marketing...………Feb. Actual..……………......$80
Marketing...………Feb Budget...................$85


I need to transform the table so there is four columns that looks like this:


Category..........Month.........................Actual................Budget
Sales...…………….Jan...........……………......$100..................$90
Sales................Feb...........................$200...................$250
Legal.......…………Jan...…………….............$500.................$400
Legal.......…………Feb.............……………...$550..................$450
Marketing...………Jan.........……………......$45.....................$40
Marketing...………Feb.........……………......$80......................$85


How do I get it into the above format?
 
Last edited:

Excel Facts

How to calculate loan payments in Excel?
Use the PMT function: =PMT(5%/12,60,-25000) is for a $25,000 loan, 5% annual interest, 60 month loan.
Code:
let
    Source = Excel.CurrentWorkbook(){[Name="Table1"]}[Content],
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"Category", type text}, {"Month", type text}, {"Amount", Int64.Type}}),
    #"Split Column by Delimiter" = Table.SplitColumn(#"Changed Type", "Month", Splitter.SplitTextByDelimiter(" ", QuoteStyle.Csv), {"Month.1", "Month.2"}),
    #"Changed Type1" = Table.TransformColumnTypes(#"Split Column by Delimiter",{{"Month.1", type text}, {"Month.2", type text}}),
    #"Pivoted Column" = Table.Pivot(#"Changed Type1", List.Distinct(#"Changed Type1"[Month.2]), "Month.2", "Amount", List.Sum)
in
    #"Pivoted Column"
 
Upvote 0

Forum statistics

Threads
1,213,517
Messages
6,114,089
Members
448,548
Latest member
harryls

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