My input data is running sum

Thanks Thanks:  0
Likes Likes:  0
Results 1 to 2 of 2

Thread: My input data is running sum

  1. #1
    New Member
    Join Date
    May 2016
    Posts
    3
    Post Thanks / Like
    Mentioned
    0 Post(s)
    Tagged
    0 Thread(s)

    Default My input data is running sum


    My input data is running sum
    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

  2. #2
    Board Regular MarcelBeug's Avatar
    Join Date
    Apr 2014
    Posts
    1,811
    Post Thanks / Like
    Mentioned
    0 Post(s)
    Tagged
    0 Thread(s)

    Default Re: My input data is running sum

      
    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"
    Specializing in Power Query (M).
    Using Excel 2007 (Dutch) and Excel 2016 (Office 365 ProPlus) (Dutch/English), both on Windows 10.
    Array formulas can be recognised by the {} Excel puts around it automatically when you press Ctrl+Shift+Enter upon formula entry.

User Tag List

Tags for this Thread

Like this thread? Share it with others

Like this thread? Share it with others

Posting Permissions

  • You may not post new threads
  • You may not post replies
  • You may not post attachments
  • You may not edit your posts
  •  

 

 
DMCA.com