Skip to main content
cancel
Showing results for 
Search instead for 
Did you mean: 

Find everything you need to get certified on Fabric—skills challenges, live sessions, exam prep, role guidance, and more. Get started

Reply
tolrahC
Regular Visitor

Sub aggregation between records

Hi,

 

With the following table

 

TimestampWoodFuel
2017-02-16 01:00300 
2017-02-16 02:00 30
2017-02-16 03:00 40
2017-02-16 06:00 50
2017-02-16 12:00180 

 

I'd like to get an aggregation of the Fuel column for the values between each Wood column value.  Is that possible directly within PowerBI?

 

In my example I would expect a sum value of 120 for 2017-02-16 01:00.

 

Thank you

1 ACCEPTED SOLUTION

An "Artist Impression" in this video (explaining the code below) how it could look like in Power Query with the data from an Excel file.

 

let
    Source = Excel.Workbook(File.Contents("C:\Users\Marcel\Documents\Forum bijdragen\Power BI Community\Subaggregation between values.xlsx"), null, true),
    Tabel1_Table = Source{[Item="Tabel1",Kind="Table"]}[Data],
    #"Changed Type" = Table.TransformColumnTypes(Tabel1_Table,{{"Timestamp", type datetime}, {"Wood", Int64.Type}, {"Fuel", Int64.Type}}),
    #"Added Index" = Table.AddIndexColumn(#"Changed Type", "Index", 0, 1),
    #"Added Custom" = Table.AddColumn(#"Added Index", "StartIndex", each if [Wood] = null then [Index] else null, Int64.Type),
    #"Filled Up" = Table.FillUp(#"Added Custom",{"StartIndex"}),
    #"Added Custom1" = Table.AddColumn(#"Filled Up", "EndIndex+1", each if [Wood] <> null then [Index] else null),
    #"Filled Up1" = Table.FillUp(#"Added Custom1",{"EndIndex+1"}),
    #"Added Index1" = Table.AddIndexColumn(#"Filled Up1", "Index.1", 1, 1),
    #"Merged Queries" = Table.NestedJoin(#"Added Index1",{"Index.1"},#"Added Index1",{"Index"},"NewColumn",JoinKind.LeftOuter),
    #"Removed Columns" = Table.RemoveColumns(#"Merged Queries",{"Index", "EndIndex+1", "Index.1"}),
    #"Expanded NewColumn" = Table.ExpandTableColumn(#"Removed Columns", "NewColumn", {"EndIndex+1"}, {"EndIndex+1"}),
    #"Inserted Subtraction" = Table.AddColumn(#"Expanded NewColumn", "Count", each [#"EndIndex+1"] - [StartIndex], type number),
    #"Added Custom2" = Table.AddColumn(#"Inserted Subtraction", "TotalFuel", each if [Wood] <> null and [StartIndex] <> null then List.Sum(List.Range(#"Removed Columns"[Fuel],[StartIndex],[Count])) else null),
    #"Removed Columns1" = Table.RemoveColumns(#"Added Custom2",{"StartIndex", "EndIndex+1", "Count"})
in
    #"Removed Columns1"
Specializing in Power Query Formula Language (M)

View solution in original post

6 REPLIES 6
Phil_Seamark
Microsoft Employee
Microsoft Employee

It would be a lot easier if you could have a 4th column with something like a JobID to link the records together.  That way the dax would just be a simple SUM over the Fuel column.  Is there any extra data you can find?

 

But I will post some DAX in a tick to show you how you can do it without a jobID

 

TimestampJobIDWoodFuel
2017-02-16 01:001300 
2017-02-16 02:001 30
2017-02-16 03:001 40
2017-02-16 06:001 50
2017-02-16 12:002180 

 

 


To learn more about DAX visit : aka.ms/practicalDAX

Proud to be a Datanaut!

Thanks Phil_Seamark,

 

If you can show me to do it without a jobid it would be appreciated.

Here is what I have so far and as you can see there are a few steps.

 

I probably need more data from you to test the ranking is working correctly.

 

I'm guessing it will be easier to do in your source data or via the query editor in Power Query.

 

Table = var d = SELECTCOLUMNS(
                        FILTER('Table1',
                            Table1[Wood] <> BLANK()
                            ),
                "Timestamp" , 'Table1'[Timestamp] ,
                "Wood" , 'Table1'[Wood] 
                )
        var r = SELECTCOLUMNS(d, "Timestamp" , [Timestamp] , "Wood" , [Wood],  "Rank" ,  RANKX(d, [Timestamp],,ASC))    
        var l = SELECTCOLUMNS(r,"rank",[Rank]-1 , "EndTime" , [Timestamp])
        var p = SELECTCOLUMNS(r,"rank",[Rank] , "StartTime" , [Timestamp], "Wood2" , [Wood])
        var x = NATURALINNERJOIN(p,l)
        var f = CROSSJOIN(x,Table1)  
        var y = filter(f,'Table1'[Timestamp]< [EndTime] && 'Table1'[Timestamp]>=[StartTime])
        return SELECTCOLUMNS(y,"Wood",[Wood2] , "Time" , [Timestamp] , "Fuel" , [Fuel])

To learn more about DAX visit : aka.ms/practicalDAX

Proud to be a Datanaut!

Wow @Phil_Seamark, that's some code to learn from 🙂

 

Actually in the query-editor, it would be pretty easy to create an additional column with the desired Timestamp, one can then simply aggregate on it:

 

1) Add a column with a forumla like this: if [Wood] <> null then [Timestamp] else null

2) Check this new column, rightclick your mouse and Fill-down the values. This will allocate the Timestamp "from above" to all the following rows until the next row with an entry in "Wood".

 

If the blanks in the wood-column are not null, you might need to adjust your formula like this:

 

if [Wood] <> "" then [Timestamp] else null

Imke Feldmann (The BIccountant)

If you liked my solution, please give it a thumbs up. And if I did answer your question, please mark this post as a solution. Thanks!

How to integrate M-code into your solution -- How to get your questions answered quickly -- How to provide sample data -- Check out more PBI- learning resources here -- Performance Tipps for M-queries

@ImkeF Just because something can be done in DAX doesn't mean it should be.  I'd say my approach (if correct) wouldn't be memory efficient and If it was something I was working on I would definitely push the transform upstream to Power Query or further if poss.

 

 


To learn more about DAX visit : aka.ms/practicalDAX

Proud to be a Datanaut!

An "Artist Impression" in this video (explaining the code below) how it could look like in Power Query with the data from an Excel file.

 

let
    Source = Excel.Workbook(File.Contents("C:\Users\Marcel\Documents\Forum bijdragen\Power BI Community\Subaggregation between values.xlsx"), null, true),
    Tabel1_Table = Source{[Item="Tabel1",Kind="Table"]}[Data],
    #"Changed Type" = Table.TransformColumnTypes(Tabel1_Table,{{"Timestamp", type datetime}, {"Wood", Int64.Type}, {"Fuel", Int64.Type}}),
    #"Added Index" = Table.AddIndexColumn(#"Changed Type", "Index", 0, 1),
    #"Added Custom" = Table.AddColumn(#"Added Index", "StartIndex", each if [Wood] = null then [Index] else null, Int64.Type),
    #"Filled Up" = Table.FillUp(#"Added Custom",{"StartIndex"}),
    #"Added Custom1" = Table.AddColumn(#"Filled Up", "EndIndex+1", each if [Wood] <> null then [Index] else null),
    #"Filled Up1" = Table.FillUp(#"Added Custom1",{"EndIndex+1"}),
    #"Added Index1" = Table.AddIndexColumn(#"Filled Up1", "Index.1", 1, 1),
    #"Merged Queries" = Table.NestedJoin(#"Added Index1",{"Index.1"},#"Added Index1",{"Index"},"NewColumn",JoinKind.LeftOuter),
    #"Removed Columns" = Table.RemoveColumns(#"Merged Queries",{"Index", "EndIndex+1", "Index.1"}),
    #"Expanded NewColumn" = Table.ExpandTableColumn(#"Removed Columns", "NewColumn", {"EndIndex+1"}, {"EndIndex+1"}),
    #"Inserted Subtraction" = Table.AddColumn(#"Expanded NewColumn", "Count", each [#"EndIndex+1"] - [StartIndex], type number),
    #"Added Custom2" = Table.AddColumn(#"Inserted Subtraction", "TotalFuel", each if [Wood] <> null and [StartIndex] <> null then List.Sum(List.Range(#"Removed Columns"[Fuel],[StartIndex],[Count])) else null),
    #"Removed Columns1" = Table.RemoveColumns(#"Added Custom2",{"StartIndex", "EndIndex+1", "Count"})
in
    #"Removed Columns1"
Specializing in Power Query Formula Language (M)

Helpful resources

Announcements
Sept PBI Carousel

Power BI Monthly Update - September 2024

Check out the September 2024 Power BI update to learn about new features.

September Hackathon Carousel

Microsoft Fabric & AI Learning Hackathon

Learn from experts, get hands-on experience, and win awesome prizes.

Sept NL Carousel

Fabric Community Update - September 2024

Find out what's new and trending in the Fabric Community.