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

Register now to learn Fabric in free live sessions led by the best Microsoft experts. From Apr 16 to May 9, in English and Spanish.

Reply
PZUDGW
Helper I
Helper I

Aggregate table for dataflow

I'd like to aggregate a table for my dataflow.  The table is down below. I'd like to have:

  • for each distinct REFOBJECT ID,
  • the latest PMCVALIDFROM,
  • and corresponding PMCRENTAMOUNT + PMCSCORINGPOINT

Can I use the option 'Group by' and if so, how?

Knipsel.JPG

1 ACCEPTED SOLUTION
Jimmy801
Community Champion
Community Champion

Hello @PZUDGW 

 

use Table.Group and within the group-function Table.Max to get your desired result. Here an example

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WclTSUTI01jM01DMyADHBOFYHKmEBlzACY7iEqZ6hEUTCGIxBEk5AloGFnoGhnqElilEwCSOIBMIoJ4jlBsYQCahRsQA=", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [#"REFOBJECT ID" = _t, PMCVALIDFROM = _t, PMCRENTAMOUNT = _t, PMCSCORINGPOINT = _t]),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"REFOBJECT ID", type text}, {"PMCVALIDFROM", type date}, {"PMCRENTAMOUNT", Int64.Type}, {"PMCSCORINGPOINT", Int64.Type}}, "de-DE"),
    #"Grouped Rows" = Table.Group(#"Changed Type", {"REFOBJECT ID"}, {{"LastVALIDFROMROW", each Table.Max(_, "PMCVALIDFROM"), type record}}),
    #"Expanded LastVALIDFROMROW" = Table.ExpandRecordColumn(#"Grouped Rows", "LastVALIDFROMROW", {"PMCVALIDFROM", "PMCRENTAMOUNT", "PMCSCORINGPOINT"}, {"PMCVALIDFROM", "PMCRENTAMOUNT", "PMCSCORINGPOINT"})
in
    #"Expanded LastVALIDFROMROW"

 

Copy paste this code to the advanced editor in a new blank query to see how the solution works.

If this post helps or solves your problem, please mark it as solution (to help other users find useful content and to acknowledge the work of users that helped you)
Kudoes are nice too

Have fun

Jimmy

View solution in original post

2 REPLIES 2
PZUDGW
Helper I
Helper I

Works great!

 

Thanks for your help

Jimmy801
Community Champion
Community Champion

Hello @PZUDGW 

 

use Table.Group and within the group-function Table.Max to get your desired result. Here an example

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WclTSUTI01jM01DMyADHBOFYHKmEBlzACY7iEqZ6hEUTCGIxBEk5AloGFnoGhnqElilEwCSOIBMIoJ4jlBsYQCahRsQA=", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [#"REFOBJECT ID" = _t, PMCVALIDFROM = _t, PMCRENTAMOUNT = _t, PMCSCORINGPOINT = _t]),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"REFOBJECT ID", type text}, {"PMCVALIDFROM", type date}, {"PMCRENTAMOUNT", Int64.Type}, {"PMCSCORINGPOINT", Int64.Type}}, "de-DE"),
    #"Grouped Rows" = Table.Group(#"Changed Type", {"REFOBJECT ID"}, {{"LastVALIDFROMROW", each Table.Max(_, "PMCVALIDFROM"), type record}}),
    #"Expanded LastVALIDFROMROW" = Table.ExpandRecordColumn(#"Grouped Rows", "LastVALIDFROMROW", {"PMCVALIDFROM", "PMCRENTAMOUNT", "PMCSCORINGPOINT"}, {"PMCVALIDFROM", "PMCRENTAMOUNT", "PMCSCORINGPOINT"})
in
    #"Expanded LastVALIDFROMROW"

 

Copy paste this code to the advanced editor in a new blank query to see how the solution works.

If this post helps or solves your problem, please mark it as solution (to help other users find useful content and to acknowledge the work of users that helped you)
Kudoes are nice too

Have fun

Jimmy

Helpful resources

Announcements
Microsoft Fabric Learn Together

Microsoft Fabric Learn Together

Covering the world! 9:00-10:30 AM Sydney, 4:00-5:30 PM CET (Paris/Berlin), 7:00-8:30 PM Mexico City

PBI_APRIL_CAROUSEL1

Power BI Monthly Update - April 2024

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

April Fabric Community Update

Fabric Community Update - April 2024

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

Top Solution Authors
Top Kudoed Authors