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
Hannisky
Frequent Visitor

Help with List generate

I am trying to get a sum of [Amt1] where [Dt2] is larger than [Dt1] (or Blank). The tricky part is that rows from future dates should be excluded. 
I'm trying to do this via List.Generate but am not getting the correct syntax. Or if this is the correct approach. Any ideas? 
The result should be sum of [Amt1] for each [Dt1], I will later remove [Dt2] and duplicates so as to only have one result for each [Dt1]. 

 

Hannisky_0-1703061627001.png

I'm trying to generate List where for each DT1 
- exclude other Dt1 rows that are larger then current row.

- only include Dt2 rows that are larger than current row or blank.

(i.e exclude rows where Dt1>(current) Dt1  , Dt1 <=(all) Dt2) 

- Total Amt1 for all included rows. 

- Ideally Amt2 should contain only the totals for the selection above. 

(* excuse typo, date below should be 2023-11-30)

Hannisky_3-1703062576958.png

Hannisky_4-1703062715978.png

 

 

 

 

 

 

1 ACCEPTED SOLUTION
v-xinruzhu-msft
Community Support
Community Support

Hi @Hannisky 

You can put the following code to advanced editor in power query

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("hZJBDoAgDAT/wtmElkIsbyH8/xsaIaTKNiYerDvCZKG1kChJ5BSFw/EemEI/IMBR6Bl24H7Efl6oGbIL0FikAOAr9Ppv2RmAgLG4wFwhuwBSs0AdOzDIP2YVmIuXg8rqT2M2B1Y21r03heeoP10pKLt4Oe33S/cmgZR99+xOV24q9Qs=", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [Dt1 = _t, Dt2 = _t, Amt1 = _t]),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"Dt1", type date}, {"Dt2", type date}, {"Amt1", Int64.Type}}),
    #"Added Custom" = Table.AddColumn(#"Changed Type", "Amt2", each let 
_select=Table.SelectRows(#"Changed Type",(x)=>x[Dt1]<=[Dt1] and (x[Dt2]>x[Dt1] or x[Dt2]=null))
in List.Sum(_select[Amt1]))
in
    #"Added Custom"

Output

vxinruzhumsft_0-1703141841663.png

Best Regards!

Yolo Zhu

If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.

 

View solution in original post

2 REPLIES 2
v-xinruzhu-msft
Community Support
Community Support

Hi @Hannisky 

You can put the following code to advanced editor in power query

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("hZJBDoAgDAT/wtmElkIsbyH8/xsaIaTKNiYerDvCZKG1kChJ5BSFw/EemEI/IMBR6Bl24H7Efl6oGbIL0FikAOAr9Ppv2RmAgLG4wFwhuwBSs0AdOzDIP2YVmIuXg8rqT2M2B1Y21r03heeoP10pKLt4Oe33S/cmgZR99+xOV24q9Qs=", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [Dt1 = _t, Dt2 = _t, Amt1 = _t]),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"Dt1", type date}, {"Dt2", type date}, {"Amt1", Int64.Type}}),
    #"Added Custom" = Table.AddColumn(#"Changed Type", "Amt2", each let 
_select=Table.SelectRows(#"Changed Type",(x)=>x[Dt1]<=[Dt1] and (x[Dt2]>x[Dt1] or x[Dt2]=null))
in List.Sum(_select[Amt1]))
in
    #"Added Custom"

Output

vxinruzhumsft_0-1703141841663.png

Best Regards!

Yolo Zhu

If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.

 

Hi, yes thank you so much 🙏 This was exactly what I needed. I owe you a cup of hot cocoa or something 😊
One thing I did change the inner loop (x) to check against the outer record [Dt1] instead of itself x[Dt1], in case anyone reuses the code. Both work but give slightly different results. 

Changed this: 

and (x[Dt2]>x[Dt1] or x[Dt2]=null))

to this...

and (x[Dt2]>[Dt1] or x[Dt2]=null))

 ...worked like a charm. 

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