• Skip to main content
  • Skip to header right navigation
  • Skip to site footer

My Online Training Hub

Learn Dashboards, Excel, Power BI, Power Query, Power Pivot

  • Courses
  • Pricing
    • Free Courses
    • Power BI Course
    • Excel Power Query Course
    • Power Pivot and DAX Course
    • Excel Dashboard Course
    • Excel PivotTable Course – Quick Start
    • Advanced Excel Formulas Course
    • Excel Expert Advanced Excel Training
    • Excel Tables Course
    • Excel, Word, Outlook
    • Financial Modelling Course
    • Excel PivotTable Course
    • Excel for Customer Service Professionals
    • Excel for Operations Management Course
    • Excel for Decision Making Under Uncertainty Course
    • Excel for Finance Course
    • Excel Analysis ToolPak Course
    • Multi-User Pricing
  • Resources
    • Free Downloads
    • Excel Functions Explained
    • Excel Formulas
    • Excel Add-ins
    • IF Function
      • Excel IF Statement Explained
      • Excel IF AND OR Functions
      • IF Formula Builder
    • Time & Dates in Excel
      • Excel Date & Time
      • Calculating Time in Excel
      • Excel Time Calculation Tricks
      • Excel Date and Time Formatting
    • Excel Keyboard Shortcuts
    • Excel Custom Number Format Guide
    • Pivot Tables Guide
    • VLOOKUP Guide
    • ALT Codes
    • Excel VBA & Macros
    • Excel User Forms
    • VBA String Functions
  • Members
    • Login
    • Password Reset
  • Blog
  • Excel Webinars
  • Excel Forum
    • Register as Forum Member

How to Power Query the last row of each table on en Excel workbook?|Power Query|Excel Forum|My Online Training Hub

You are here: Home / How to Power Query the last row of each table on en Excel workbook?|Power Query|Excel Forum|My Online Training Hub
Avatar
sp_LogInOut Log In sp_Registration Register
sp_Search Search
Advanced Search|Last Search Results
Search
Forum Scope




Match



Forum Options



Minimum search word length is 3 characters - maximum search word length is 84 characters
sp_Search Search
sp_RankInfo
Lost password?
sp_CrumbsHome HomeExcel ForumPower QueryHow to Power Query the last row of …
sp_PrintTopic sp_TopicIcon
How to Power Query the last row of each table on en Excel workbook?
Avatar
Jim Chen
Member
Members

Power BI
Level 0
Forum Posts: 54
Member Since:
February 20, 2019
sp_UserOfflineSmall Offline
1
December 31, 2019 - 3:08 pm
sp_Permalink sp_Print

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

Avatar
Velouria
London or thereabouts
Moderator
Members


Trusted Members

Moderators
Level 4
Forum Posts: 615
Member Since:
November 1, 2018
sp_UserOfflineSmall Offline
2
December 31, 2019 - 7:36 pm
sp_Permalink sp_Print

In the PQ UI there is a Keep Rows dropdown that allows you to specify to keep the bottom n rows. Just choose 1 for the number to keep.

Avatar
Jim Chen
Member
Members

Power BI
Level 0
Forum Posts: 54
Member Since:
February 20, 2019
sp_UserOfflineSmall Offline
3
January 2, 2020 - 5:42 am
sp_Permalink sp_Print

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

Avatar
Velouria
London or thereabouts
Moderator
Members


Trusted Members

Moderators
Level 4
Forum Posts: 615
Member Since:
November 1, 2018
sp_UserOfflineSmall Offline
4
January 2, 2020 - 6:37 pm
sp_Permalink sp_Print

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!

sp_Feed
Go to top
Forum Timezone: Australia/Brisbane
Most Users Ever Online: 245
Currently Online: Jeff Krueger, Kylara Papenfuss, Janset Beyaz, Shawn Barwick, Nada Perovic
Guest(s) 8
Currently Browsing this Page:
1 Guest(s)
Top Posters:
SunnyKow: 1432
Anders Sehlstedt: 870
Purfleet: 412
Frans Visser: 346
David_Ng: 306
lea cohen: 219
A.Maurizio: 202
Jessica Stewart: 202
Aye Mu: 201
jaryszek: 183
Newest Members:
John Chisholm
vexokeb sdfg
John Jack
Malcolm Toy
Ray-Yu Yang
George Shihadeh
Naomi Rumble
Uwe von Gostomski
Jonathan Jones
drsven
Forum Stats:
Groups: 3
Forums: 24
Topics: 6212
Posts: 27236

 

Member Stats:
Guest Posters: 49
Members: 31889
Moderators: 3
Admins: 4
Administrators: Mynda Treacy, Philip Treacy, Catalin Bombea, FT
Moderators: MOTH Support, Velouria, Riny van Eekelen
© Simple:Press —sp_Information

Sidebar

Blog Categories

  • Excel
  • Excel Charts
  • Excel Dashboard
  • Excel Formulas
  • Excel PivotTables
  • Excel Shortcuts
  • Excel VBA
  • General Tips
  • Online Training
  • Outlook
  • Power Apps
  • Power Automate
  • Power BI
  • Power Pivot
  • Power Query
microsoft mvp logo
trustpilot excellent rating
Secured by Sucuri Badge
MyOnlineTrainingHub on YouTube Mynda Treacy on Linked In Mynda Treacy on Instagram Mynda Treacy on Twitter Mynda Treacy on Pinterest MyOnlineTrainingHub on Facebook
 

Company

  • About My Online Training Hub
  • Disclosure Statement
  • Frequently Asked Questions
  • Guarantee
  • Privacy Policy
  • Terms & Conditions
  • Testimonials
  • Become an Affiliate

Support

  • Contact
  • Forum
  • Helpdesk - For Technical Issues

Copyright © 2023 · My Online Training Hub · All Rights Reserved. Microsoft and the Microsoft Office logo are trademarks or registered trademarks of Microsoft Corporation in the United States and/or other countries. Product names, logos, brands, and other trademarks featured or referred to within this website are the property of their respective trademark holders.