February 20, 2019
I use power query to create a table for each bank or credit card account and save to a sheet. Each sheet holds one table for each account. Each table contains all transactions for each account, and the last row (or the latest by date) has a balance. All tables are stored in a workbook.
How can I use Power Query to get the last row with the balance from each table and create a summary table which holds balances for each account?
Thanks!
JIm
Trusted Members
Moderators
November 1, 2018
February 20, 2019
Velouria,
Thank you very much for your help.
After reading your post I realized that I did not make a correct statement about my question.
I have many tables saved on a workbook. There are many sheets such as Sheet A, Sheet B, Sheet C..... and there is an excel table on each sheet such as Table A, Table B, Table C. Each table represents a bank account and the last row of each table is the current balance.
I want to use Power Query to aggregate each balance (the last row of a table) and load it to a Table or a Pivot Table. I use "=Excel.CurrentWorkbook()" to extract all tables at once out of this workbook, so the "Keep Rows" won't work in this scenario unless that I query one table at a time.
Does anyone have a better way to accomplish this task?
Thanks!
Jim
Trusted Members
Moderators
November 1, 2018
You can still do what I suggested, you just need to make that part into a function. Create a query that loads one of the tables in, and then keeps just the last row. Your query should look something like:
let
Source = Excel.CurrentWorkbook(){[Name="Table1"]}[Content],
#"Changed Type" = Table.TransformColumnTypes(Source,{{"Header1", type text}}),
#"Kept Last Rows" = Table.LastN(#"Changed Type", 1)
in
#"Kept Last Rows"
Now all you do is add a parameter and replace the table name with it, like so:
(myTable)=>
let
Source = Excel.CurrentWorkbook(){[Name=myTable]}[Content],
#"Changed Type" = Table.TransformColumnTypes(Source,{{"Header1", type text}}),
#"Kept Last Rows" = Table.LastN(#"Changed Type", 1)
in
#"Kept Last Rows"
then change the name of the query to something like fnLastRowOnly
New create a new blank query and just enter =Excel.CurrentWorkbook() in the formula bar and apply any filtering necessary to get just the Tables visible. Then add a new calculated column using the formula =fnLastRowOnly([Name]) which will return a one row table for each Table. Expand that, remove any columns you don't want and away you go.
Note: if you return the results as a table to the worksheet, make sure to go back in and edit your query to exclude that result Table otherwise its last row will keep getting added as another result!
1 Guest(s)