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

The Power BI Data Visualization World Championships is back! Get ahead of the game and start preparing now! Learn more

Reply
Swalker
Frequent Visitor

PowerQuery M Running Total Date and LedgerKey

Hi All,

 

I am trying to convert Transactionlines (TL) into periodic snapshot for a balance sheet model using PowerQuery.

The TL table is loaded in PQ and has Date, AccountCode and Amount:

TL.GIF

 

Next step is to create a new Column RTTable with EndOfMonth Dates - and for each AccountCode i like a Running Total. 

See picture for Accountcode 1600. Next to 1600 should be another Account Code column etc.

I am able to code this in DAX (see code below for eg AccountCode 1600) but howis this done in PowerQuery ?

Once realised i will unpivot the RTTable and it is then input for the balance sheet model.

 

Desired tabe:

RT.GIF

DAX code:

1600 =var CurrentDate=RTTable[Date]
var CurrentLedger=1600
var FilteredTable = FILTER('TranactionLines','TransactionLines'[AltDate]<=CurrentDate && 'TransactionLines'[AccountKey]=CurrentLedger)
return
	CALCULATE(SUM('TransactionLines'[Amount]),FilteredTable)

 

 

any help is appreciated

1 ACCEPTED SOLUTION
Anonymous
Not applicable

Hi @Swalker ,

 

Please refer to the following steps:

let
  Source = Table.FromRows(
    Json.Document(
      Binary.Decompress(
        Binary.FromText(
          "ddBRDoQwCATQu/TbHWFaWjyL8f7XsJqazZb1i4+XYQj7nnTVlaKWlmR2D6WALR3LD2oV6eOjxWA5qPFSGlgfkxAlSsBeyrv0a/NWLRAP2IO5j9ogOSZHpStUH+W8lyAj6rhWvGGL4dFrjj/ZUdsE5VWnxTm86c3H1e7wqFLKpb5t6Hic", 
          BinaryEncoding.Base64
        ), 
        Compression.Deflate
      )
    ), 
    let
      _t = ((type nullable text) meta [Serialized.Text = true])
    in
      type table [AltDate = _t, GLAccountCode = _t, AmountDC = _t]
  ), 
  #"Changed Type" = Table.TransformColumnTypes(
    Source, 
    {{"AltDate", type date}, {"GLAccountCode", Int64.Type}, {"AmountDC", type number}}
  ), 
  #"Grouped Rows" = Table.Group(
    #"Changed Type", 
    {"GLAccountCode"}, 
    {{"Data", each Table.AddIndexColumn(_, "Index", 1, 1), type table}}
  ), 
  Custom1 = Table.TransformColumns(
    #"Grouped Rows", 
    {
      "Data", 
      (x) => Table.AddColumn(x, "Running Total", each List.Sum(List.FirstN(x[AmountDC], [Index])))
    }
  ), 
  #"Expanded Data" = Table.ExpandTableColumn(
    Custom1, 
    "Data", 
    {"AltDate", "Running Total"}, 
    {"AltDate", "Running Total"}
  ), 
  #"Pivoted Column" = Table.Pivot(
    Table.TransformColumnTypes(#"Expanded Data", {{"GLAccountCode", type text}}, "en-US"), 
    List.Distinct(
      Table.TransformColumnTypes(#"Expanded Data", {{"GLAccountCode", type text}}, "en-US")[
        GLAccountCode
      ]
    ), 
    "GLAccountCode", 
    "Running Total", 
    List.Sum
  ), 
  #"Filled Down" = Table.FillDown(
    #"Pivoted Column", 
    {"5515", "1600", "1520", "5512", "5513", "1100", "440"}
  )
in
  #"Filled Down"

result:

vcgaomsft_0-1674118319140.png

Best Regards,
Gao

Community Support Team

 

If there is any post helps, then please consider Accept it as the solution  to help the other members find it more quickly. If I misunderstand your needs or you still have problems on it, please feel free to let us know. Thanks a lot!

How to get your questions answered quickly --  How to provide sample data in the Power BI Forum

View solution in original post

2 REPLIES 2
Anonymous
Not applicable

Hi @Swalker ,

 

Please refer to the following steps:

let
  Source = Table.FromRows(
    Json.Document(
      Binary.Decompress(
        Binary.FromText(
          "ddBRDoQwCATQu/TbHWFaWjyL8f7XsJqazZb1i4+XYQj7nnTVlaKWlmR2D6WALR3LD2oV6eOjxWA5qPFSGlgfkxAlSsBeyrv0a/NWLRAP2IO5j9ogOSZHpStUH+W8lyAj6rhWvGGL4dFrjj/ZUdsE5VWnxTm86c3H1e7wqFLKpb5t6Hic", 
          BinaryEncoding.Base64
        ), 
        Compression.Deflate
      )
    ), 
    let
      _t = ((type nullable text) meta [Serialized.Text = true])
    in
      type table [AltDate = _t, GLAccountCode = _t, AmountDC = _t]
  ), 
  #"Changed Type" = Table.TransformColumnTypes(
    Source, 
    {{"AltDate", type date}, {"GLAccountCode", Int64.Type}, {"AmountDC", type number}}
  ), 
  #"Grouped Rows" = Table.Group(
    #"Changed Type", 
    {"GLAccountCode"}, 
    {{"Data", each Table.AddIndexColumn(_, "Index", 1, 1), type table}}
  ), 
  Custom1 = Table.TransformColumns(
    #"Grouped Rows", 
    {
      "Data", 
      (x) => Table.AddColumn(x, "Running Total", each List.Sum(List.FirstN(x[AmountDC], [Index])))
    }
  ), 
  #"Expanded Data" = Table.ExpandTableColumn(
    Custom1, 
    "Data", 
    {"AltDate", "Running Total"}, 
    {"AltDate", "Running Total"}
  ), 
  #"Pivoted Column" = Table.Pivot(
    Table.TransformColumnTypes(#"Expanded Data", {{"GLAccountCode", type text}}, "en-US"), 
    List.Distinct(
      Table.TransformColumnTypes(#"Expanded Data", {{"GLAccountCode", type text}}, "en-US")[
        GLAccountCode
      ]
    ), 
    "GLAccountCode", 
    "Running Total", 
    List.Sum
  ), 
  #"Filled Down" = Table.FillDown(
    #"Pivoted Column", 
    {"5515", "1600", "1520", "5512", "5513", "1100", "440"}
  )
in
  #"Filled Down"

result:

vcgaomsft_0-1674118319140.png

Best Regards,
Gao

Community Support Team

 

If there is any post helps, then please consider Accept it as the solution  to help the other members find it more quickly. If I misunderstand your needs or you still have problems on it, please feel free to let us know. Thanks a lot!

How to get your questions answered quickly --  How to provide sample data in the Power BI Forum

jbwtp
Memorable Member
Memorable Member

Hi @Swalker,

 

there are many examples on this platform already:

e.g. Solved: Re: Cumulative sum in Power query editor - Microsoft Power BI Community 

or here using Google search on cumulative total: Running Total in Power Query (Ultimate Guide) - BI Gorilla

 

Cheers,

John

Helpful resources

Announcements
Power BI DataViz World Championships

Power BI Dataviz World Championships

The Power BI Data Visualization World Championships is back! Get ahead of the game and start preparing now!

December 2025 Power BI Update Carousel

Power BI Monthly Update - December 2025

Check out the December 2025 Power BI Holiday Recap!

FabCon Atlanta 2026 carousel

FabCon Atlanta 2026

Join us at FabCon Atlanta, March 16-20, for the ultimate Fabric, Power BI, AI and SQL community-led event. Save $200 with code FABCOMM.

Top Solution Authors