• 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

Custom function|Power Query|Excel Forum|My Online Training Hub

You are here: Home / Custom function|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 QueryCustom function
sp_PrintTopic sp_TopicIcon
Custom function
Avatar
Dana Sarbulescu
Member
Members

Power Query
Level 0
Forum Posts: 16
Member Since:
October 7, 2022
sp_UserOfflineSmall Offline
1
May 14, 2023 - 5:16 am
sp_Permalink sp_Print

Hi,

I have a table of timesheets showing the daily number of hours billed by every employee at different clients. They bill at different bill rates across clients. I would like to know the effective bill rate by employee, by month. The effective bill rate is calculated as Input hours x Bill rate for every employees timesheet divided by total input hours in the month for every employee. How can I write this as a function in Power Query? 

And to take it a step further, ideally i would be able to present the result of the effective bill rate in a pivot table so that the results can be filtered for a desired employee and if possible also use a slider to determine the period over which the effective bill rate should be determined. See attached raw data file.

I was trying to represent this in Power BI via a DAX SUMX measure, but the slider filters for the page don't seem to apply in measures, so I thought i would try to solve this in Power Query instead.

 

Thank you!

Dana

Avatar
Alan Sidman
Steamboat Springs, CO
Member
Members


Trusted Members
Level 0
Forum Posts: 150
Member Since:
October 18, 2018
sp_UserOfflineSmall Offline
2
May 14, 2023 - 9:37 am
sp_Permalink sp_Print sp_EditHistory

Does this look like what you are expecting.  You did not give us a mocked up solution so I am guessing

 

Name                                      MonthBill    Rates                Total Input Hours       Division
Employee 2 1 7005 98.33 71.23970304
Employee 2 2 5600 142.98 39.16631696
Employee 2 3 6725 161.09 41.74684959
Employee 2 4 5760 109.16 52.76658116
Employee 1 1 8430 189.2 44.55602537
Employee 1 2 7565 168.53 44.88815048
Employee 1 3 6860 180.53 37.99922451
Employee 1 4 6520 171.51 38.01527608

If yes, then 

let
Source = Excel.CurrentWorkbook(){[Name="Table1"]}[Content],
#"Changed Type" = Table.TransformColumnTypes(Source,{{"Admin rate/Base rate", type number}, {"Bill Rate", Int64.Type}}),
#"Inserted Month" = Table.AddColumn(#"Changed Type", "Month", each Date.Month([Date]), Int64.Type),
#"Grouped Rows" = Table.Group(#"Inserted Month", {"Name", "Month"}, {{"Bill Rates", each List.Sum([Bill Rate]), type nullable number}, {"Total Input Hours", each List.Sum([Input]), type number}}),
#"Inserted Division" = Table.AddColumn(#"Grouped Rows", "Division", each [Bill Rates] / [Total Input Hours], type number)
in
#"Inserted Division"

If no, then mock up what your expected results should look like.

Avatar
Dana Sarbulescu
Member
Members

Power Query
Level 0
Forum Posts: 16
Member Since:
October 7, 2022
sp_UserOfflineSmall Offline
3
May 15, 2023 - 7:55 am
sp_Permalink sp_Print

Hi,

Thanks for taking a stab at this. It's almost right, however in your calculation above you did the sum of all bill rates. Instead you should have calculated the sum of the product of input hours x bill rate for each timesheet of an employee for one month and divide that amount by total hours in that month. I know how to achieve this number with a pivot table if I also add another column in the raw data table to calculate the billed amount at each timesheet. However I am trying to obtain this number in Power Query so I can visualize it in a Power BI Dashboard and I am also trying to make the calculation dependent on the time frame selected.

See attached what the results would look like in a Pivot table (Sheet 2 of the file).

Thanks,

Dana

Avatar
Alan Sidman
Steamboat Springs, CO
Member
Members


Trusted Members
Level 0
Forum Posts: 150
Member Since:
October 18, 2018
sp_UserOfflineSmall Offline
4
May 15, 2023 - 1:05 pm
sp_Permalink sp_Print

Maybe this:  

let
Source = Excel.CurrentWorkbook(){[Name="Table1"]}[Content],
#"Changed Type" = Table.TransformColumnTypes(Source,{{"Admin rate/Base rate", type number}, {"Bill Rate", Int64.Type}}),
#"Inserted Month" = Table.AddColumn(#"Changed Type", "Month", each Date.Month([Date]), Int64.Type),
#"Inserted Multiplication" = Table.AddColumn(#"Inserted Month", "Multiplication", each [Input] * [Bill Rate], type number),
#"Renamed Columns" = Table.RenameColumns(#"Inserted Multiplication",{{"Multiplication", "BillRate x Input"}}),
#"Grouped Rows" = Table.Group(#"Renamed Columns", {"Name", "Month"}, {{"Sum Product", each List.Sum([BillRate x Input]), type number}, {"Sum Hours per EE per month", each List.Sum([Input]), type number}}),
#"Inserted Division" = Table.AddColumn(#"Grouped Rows", "Division", each [Sum Product] / [Sum Hours per EE per month], type number),
#"Renamed Columns1" = Table.RenameColumns(#"Inserted Division",{{"Division", "Result"}})
in
#"Renamed Columns1"

Name  Month  Sum Product  Sum Hours per EE per month  Result

Employee 2 1 13855.95 98.33 140.9127428
Employee 2 2 20632.55 142.98 144.3037488
Employee 2 3 22777.1 161.09 141.3936309
Employee 2 4 15168.25 109.16 138.9542873
Employee 1 1 22501.1 189.2 118.9275899
Employee 1 2 19969.05 168.53 118.4895864
Employee 1 3 22054.5 180.53 122.1652911
Employee 1 4 21034.25 171.51 122.6415369
Avatar
Dana Sarbulescu
Member
Members

Power Query
Level 0
Forum Posts: 16
Member Since:
October 7, 2022
sp_UserOfflineSmall Offline
5
May 18, 2023 - 10:24 am
sp_Permalink sp_Print

Thank you so much. Really appreciate your help!

sp_Feed
Go to top
Forum Timezone: Australia/Brisbane
Most Users Ever Online: 245
Currently Online:
Guest(s) 12
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: 216
A.Maurizio: 202
Aye Mu: 201
jaryszek: 183
Newest Members:
Melanie Ford
Isaac Felbah
Adele Glover
Hitesh Asrani
Rohan Abraham
Anthony van Riessen
Erlinda Eloriaga
Abisola Ogundele
MARTYN STERRY
Rahim Lakhani
Forum Stats:
Groups: 3
Forums: 24
Topics: 6356
Posts: 27793

 

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