Forum

Notifications
Clear all

Custom function

5 Posts
2 Users
0 Reactions
76 Views
(@optimaoffice)
Posts: 17
Eminent Member
Topic starter
 

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

 
Posted : 14/05/2023 3:16 pm
Alan Sidman
(@alansidman)
Posts: 220
Member Moderator
 

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.

 
Posted : 14/05/2023 7:37 pm
(@optimaoffice)
Posts: 17
Eminent Member
Topic starter
 

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

 
Posted : 15/05/2023 5:55 pm
Alan Sidman
(@alansidman)
Posts: 220
Member Moderator
 

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
 
Posted : 15/05/2023 11:05 pm
(@optimaoffice)
Posts: 17
Eminent Member
Topic starter
 

Thank you so much. Really appreciate your help!

 
Posted : 18/05/2023 8:24 pm
Share: