• 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
  • Blog
  • Excel Webinars
  • Excel Forum
    • Register as Forum Member

Power query very slow|Power Query|Excel Forum|My Online Training Hub

You are here: Home / Power query very slow|Power Query|Excel Forum|My Online Training Hub

vba course banner

Avatar
sp_LogInOut Log In sp_Registration Register
sp_Search Search
Advanced Search
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 QueryPower query very slow
sp_PrintTopic sp_TopicIcon
Power query very slow
Avatar
Trevor Dawkins
Member
Members
Level 0
Forum Posts: 22
Member Since:
May 17, 2019
sp_UserOfflineSmall Offline
1
November 5, 2019 - 8:02 pm
sp_Permalink sp_Print

Hello,

 I have two csv files from my heat pump, each with two columns: date in unix time + electrical input, date in unix time +heat output. Both hourly readings for up to last 5 years. Currently only the last 6 months. 

Both electrical input and heat output are cumulative  values.

Thanks to this site I found the unix time conversion for PQ and how to extract the hourly actual values :-). 

Then it's a matter of grouping by day to see the performance.

Problem is that with the current 4700 input rows, this is taking 40 mins to close and load, after waiting ages for the preview. My system is an i7 980 hex-core, GTX 950, 18GB memory and SSD, Office 365. Not the latest but no slouch. Windows shows Excel memory usage going up to above 1 GB. 

Wondering if changing to office 365 64-bit might help? Or are there other solutions to the lack of speed?

I'm sure that doing it via VBA would result in it working much quicker, but PQ is so cool! (and it's new to me...)

code shown below:

let
Source = Csv.Document(File.Contents("C:\Users\Trevor\Dropbox\Documents\_Anconalaan\Toon\ToonData\ElecUsed.csv"),[Delimiter=",", Columns=2, Encoding=1252, QuoteStyle=QuoteStyle.None]),
#"Changed Type" = Table.TransformColumnTypes(Source,{{"Column1", Int64.Type}, {"Column2", Int64.Type}}),
#"Divided Column" = Table.TransformColumns(#"Changed Type", {{"Column2", each _ / 1000, type number}}),
#"Merged Queries" = Table.NestedJoin(#"Divided Column", {"Column1"}, Energy, {"Column1"}, "Energy", JoinKind.LeftOuter),
#"Expanded Energy" = Table.ExpandTableColumn(#"Merged Queries", "Energy", {"Column2"}, {"Energy.Column2"}),
#"Renamed Columns" = Table.RenameColumns(#"Expanded Energy",{{"Column2", "KW-Tot"}, {"Energy.Column2", "H-Tot"}}),
#"Added Custom" = Table.AddColumn(#"Renamed Columns", "Date", each #datetime(1970, 1, 1, 0, 0, 0 ) + #duration(0, 0, 0, [Column1])),
#"Extracted Date" = Table.TransformColumns(#"Added Custom",{{"Date", DateTime.Date, type date}}),
#"Removed Columns" = Table.RemoveColumns(#"Extracted Date",{"Column1"}),
#"Added Index" = Table.AddIndexColumn(#"Removed Columns", "Index", 0, 1),
#"Added Custom1" = Table.AddColumn(#"Added Index", "KW-Hourly", each if [Index] > 0 then (#"Renamed Columns"{[Index]} [#"KW-Tot"]) -(#"Renamed Columns"{[Index]-1} [#"KW-Tot"]) else null),
#"Added Custom2" = Table.AddColumn(#"Added Custom1", "H-Hourly", each if [Index] > 0 then (#"Added Index"{[Index]} [#"H-Tot"]) -(#"Added Index"{[Index]-1} [#"H-Tot"]) else null),
#"Removed Columns1" = Table.RemoveColumns(#"Added Custom2",{"KW-Tot", "H-Tot", "Index"}),
#"Grouped Rows" = Table.Group(#"Removed Columns1", {"Date"}, {{"KW Daily", each List.Sum([#"KW-Hourly"]), type number}, {"H-Daily", each List.Sum([#"H-Hourly"]), type number}})
in
#"Grouped Rows"

sp_AnswersTopicSeeAnswer See Answer
Avatar
Catalin Bombea
Iasi, Romania
Admin
Level 10
Forum Posts: 1826
Member Since:
November 8, 2013
sp_UserOfflineSmall Offline
2
November 6, 2019 - 5:12 am
sp_Permalink sp_Print

You are using row context in 2 steps, #"Added Custom1"  and #"Added Custom2".

This operation is highly expensive in resource consumption, you have to consider an alternative solution to get to the same result.

Trying to imitate excel sheet formulas is not the best approach, if you can explain the logic of those 2 columns, maybe we can come up with an alternative.

Sample data will help a lot, if you can upload.

Avatar
Trevor Dawkins
Member
Members
Level 0
Forum Posts: 22
Member Since:
May 17, 2019
sp_UserOfflineSmall Offline
3
November 6, 2019 - 10:06 pm
sp_Permalink sp_Print sp_EditHistory

Hi Catalin,  the two source csv files are an hourly record of heat output and electrican input. But the values of heat and electricity are cumulative (like meter reading) and I used those two added columns to extract the actual values per hour. Basically subtracting value of previous line from current line. I've uploaded a stripped down version of the excel file, see tab "Warmtewinner"

Avatar
Catalin Bombea
Iasi, Romania
Admin
Level 10
Forum Posts: 1826
Member Since:
November 8, 2013
sp_UserOfflineSmall Offline
4
November 7, 2019 - 2:41 am
sp_Permalink sp_Print sp_EditHistory

Hi Trevor,

You'll love PQ more after this 🙂 , below is the query modified.

What I did to achieve the same results:

After your AddedIndex step, I added another Index column, but this time starting from 1 not from 0 as the previous index column.

The next trick is to Merge the current query with itself, matching Index column with Index.1 column, then expand the new column to get the columns {"KW-Tot", "H-Tot"} renamed as {"KW-Previous", "H-Previous"}. This will basically bring the next row value into the same row, as new columns. The calculated columns will be much more natural, with current row operations: [#"KW-Tot"]-[#"KW-Previous"]. Same for H-Hourly.

Now it takes 1-2 seconds to refresh.

let
Source = Csv.Document(File.Contents("C:\Users\Trevor\Dropbox\Downloads\ElecUsed.csv"),[Delimiter=",", Columns=2, Encoding=1252, QuoteStyle=QuoteStyle.None]),
#"Changed Type" = Table.TransformColumnTypes(Source,{{"Column1", Int64.Type}, {"Column2", Int64.Type}}),
#"Divided Column" = Table.TransformColumns(#"Changed Type", {{"Column2", each _ / 1000, type number}}),
#"Merged Queries" = Table.NestedJoin(#"Divided Column", {"Column1"}, Energy, {"Column1"}, "Energy", JoinKind.LeftOuter),
#"Expanded Energy" = Table.ExpandTableColumn(#"Merged Queries", "Energy", {"Column2"}, {"Energy.Column2"}),
#"Renamed Columns" = Table.RenameColumns(#"Expanded Energy",{{"Column2", "KW-Tot"}, {"Energy.Column2", "H-Tot"}}),
#"Added Custom" = Table.AddColumn(#"Renamed Columns", "Date", each #datetime(1970, 1, 1, 0, 0, 0 ) + #duration(0, 0, 0, [Column1])),
#"Extracted Date" = Table.TransformColumns(#"Added Custom",{{"Date", DateTime.Date, type date}}),
#"Removed Columns" = Table.RemoveColumns(#"Extracted Date",{"Column1"}),
#"Added Index" = Table.AddIndexColumn(#"Removed Columns", "Index", 0, 1),
#"Added Index1" = Table.AddIndexColumn(#"Added Index", "Index.1", 1, 1),
#"Merged Queries1" = Table.NestedJoin(#"Added Index1", {"Index"}, #"Added Index1", {"Index.1"}, "Added Index1", JoinKind.LeftOuter),
#"Expanded Added Index2" = Table.ExpandTableColumn(#"Merged Queries1", "Added Index1", {"KW-Tot", "H-Tot"}, {"KW-Previous", "H-Previous"}),
#"Sorted Rows" = Table.Sort(#"Expanded Added Index2",{{"Index", Order.Ascending}}),
#"Added Custom3" = Table.AddColumn(#"Sorted Rows", "kW-Hourly", each [#"KW-Tot"]-[#"KW-Previous"]),
#"Added Custom4" = Table.AddColumn(#"Added Custom3", "H-Hourly", each [#"H-Tot"]-[#"H-Previous"]),
#"Removed Columns1" = Table.RemoveColumns(#"Added Custom4",{"KW-Tot", "H-Tot", "Index"}),
#"Grouped Rows" = Table.Group(#"Removed Columns1", {"Date"}, {{"KW Daily", each List.Sum([#"kW-Hourly"]), type number}, {"H-Daily", each List.Sum([#"H-Hourly"]), type number}})
in
#"Grouped Rows"
sp_AnswersTopicAnswer
Answers Post
Avatar
Trevor Dawkins
Member
Members
Level 0
Forum Posts: 22
Member Since:
May 17, 2019
sp_UserOfflineSmall Offline
5
November 7, 2019 - 5:55 am
sp_Permalink sp_Print sp_EditHistory

Catalin, thank you so much for this! Perfect and almost instantaneous! SmileSmileSmile

sp_Feed
Go to top
Forum Timezone: Australia/Brisbane
Most Users Ever Online: 245
Currently Online: Louis Muti
Guest(s) 8
Currently Browsing this Page:
1 Guest(s)
Top Posters:
SunnyKow: 1432
Anders Sehlstedt: 873
Purfleet: 414
Frans Visser: 346
David_Ng: 306
lea cohen: 222
Jessica Stewart: 218
A.Maurizio: 202
Aye Mu: 201
jaryszek: 183
Newest Members:
Blair Gallagher
Brandi Taylor
Hafiz Ihsan Qadir
Gontran Bage
adolfo casanova
Annestine Johnpulle
Priscila Campbell
Jeff Mikles
Aaron Butler
Maurice Petterlin
Forum Stats:
Groups: 3
Forums: 24
Topics: 6369
Posts: 27852

 

Member Stats:
Guest Posters: 49
Members: 32359
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.