My input data is running sum

karlden

New Member
Joined
May 30, 2016
Messages
3
Hi

I have a file with data that I want to import to excel via power query.

All data in the file are continuous measurements of three water meters, which means that the consumption per hour is always current readings minus the previous one.
To complicate things further, you can also readings to be irregular and not done every hour.

The way I have done it under the sheet New data isnt good, but I did it just to get an example.


Is there any way I can fix this either in the power query import stage or via a formula in the power pivot?
I can not find a formula to get the consumption per hour of data that is stored as a running total.


What I want to do with this is for example some graphs as you can see in the file under the sheet Graph. So that you can monitor the water consumption at different times and occasions over time.


Thank you for your help / Johan
 

Excel Facts

Round to nearest half hour?
Use =MROUND(A2,"0:30") to round to nearest half hour. Use =CEILING(A2,"0:30") to round to next half hour.
You can add 2 Index columns, starting with 0 and 1 respectively, then merg the table with itself and perform the calculations.

Code:
let
    Source = Excel.CurrentWorkbook(){[Name="Table2"]}[Content],
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"Date", type number}, {"Area 1", Int64.Type}, {"Area 2", Int64.Type}, {"Area 3", Int64.Type}}),
    #"Added Index" = Table.AddIndexColumn(#"Changed Type", "Index", 0, 1),
    #"Added Index1" = Table.AddIndexColumn(#"Added Index", "Index.1", 1, 1),
    #"Merged Queries" = Table.NestedJoin(#"Added Index1",{"Index"},#"Added Index1",{"Index.1"},"Previous",JoinKind.LeftOuter),
    #"Expanded Previous" = Table.ExpandTableColumn(#"Merged Queries", "Previous", {"Area 1", "Area 2", "Area 3"}, {"Previous.Area 1", "Previous.Area 2", "Previous.Area 3"}),
    #"Filtered Rows" = Table.SelectRows(#"Expanded Previous", each [Previous.Area 1] <> null),
    #"Renamed Columns" = Table.RenameColumns(#"Filtered Rows",{{"Area 1", "Cumulative Area 1"}, {"Area 2", "Cumulative Area 2"},{"Area 3", "Cumulative Area 3"}}),
    #"Added Custom" = Table.AddColumn(#"Renamed Columns", "Aewa 1", each [Cumulative Area 1] - [Previous.Area 1], Int64.Type),
    #"Added Custom1" = Table.AddColumn(#"Added Custom", "Area 2", each [Cumulative Area 2] - [Previous.Area 2], Int64.Type),
    #"Added Custom2" = Table.AddColumn(#"Added Custom1", "Area 3", each [Cumulative Area 3] - [Previous.Area 3], Int64.Type),
    #"Removed Columns" = Table.RemoveColumns(#"Added Custom2",{"Cumulative Area 1", "Cumulative Area 2", "Cumulative Area 3", "Index", "Index.1", "Previous.Area 1", "Previous.Area 2", "Previous.Area 3"})
in
    #"Removed Columns"
 
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