By-line totals

dmj120

Active Member
Joined
Jan 5, 2010
Messages
286
Office Version
  1. 365
  2. 2019
  3. 2010
I am trying to create a summary table of expenses for a massive project for 35 people (each assigned a "type"). My data set is:

Type
Pay Rate
Days
Hotel
Per Diem
total
1099
15.00
15
0
50
=((pay*8)*days)+hotel+per diem -- $1850
1099
18.00
20
500
50
$3430
Internal
35.00
10
200
50
$3050
Vendor
100.00
10
0
50
.....

<tbody>
</tbody>


My summary table is:

Type
Pay
Hotel
Per Diem
Total
1099
$5280
sumifs()
sumifs()
sum(b2:d2)
Internal
Vendor

<tbody>
</tbody>

The hotel and Per Diem are easily done with sumifs(). I'm running into an issue with the types because each type has to have the individual row calculated then totaled.

It would be something like sum( (b2*8)*c2), (b3*8)*c3), etc. ) but I don't want to hard code it - more are being added everyday, so I'd like to have a simple formula to find, calculate and add everything.

Thanks for any ideas.
Josh
 

Excel Facts

Best way to learn Power Query?
Read M is for (Data) Monkey book by Ken Puls and Miguel Escobar. It is the complete guide to Power Query.
This would be a good demonstration for PowerPivot and the difference between SUM and SUMX.
SUMX is like using a helper field to do your per line calculations. It changes the evaluation order. I think that in your Table, the column "Total" is not a good label as it will conflict with the desired label in your Pivot Table.

Do you have O365 or Office 2013 Professional Plus?
 
Upvote 0
Hi,

I'm a bit confused with your description, and your SUMMARY "Pay" value of $5280 seems incorrect.
And for the Total, Doesn't "Per Diem" need to be Multiplied by Days Also ?
 
Last edited:
Upvote 0
Not sure I fully understand what you're after, but how about


Excel 2013/2016
ABCDE
1TypePay RateDaysHotelPer Diem
210991515050
31099182050050
4Internal351020050
5Vendor10010050
6
7
8
9TypePayHotelPer DiemTotal
1010994680sumifs()sumifs()sum(b2:d2)
11Internal
12Vendor
Index
Cell Formulas
RangeFormula
B10=SUMPRODUCT(--($A$2:$A$5=$A10),(B2:B5)*(C2:C5)*8)
 
Last edited:
Upvote 0
It would be something like sum( (b2*8)*c2), (b3*8)*c3), etc. ) but I don't want to hard code it - more are being added everyday, so I'd like to have a simple formula to find, calculate and add everything.

Thanks for any ideas.
Josh
You should also covert your range to a Table. Then your column formula will extend as the Table grows and the the Pivot Table will just need a refresh to see the new rows without redefining the source range.
 
Upvote 0
Yes, the per diem would be (and is) multiplied by the number of days on my spreadsheet. I was just typing out a simple version of it.

Yes you are correct, I added the totals on the SUMMARY table; whoops.:oops:
the pay summary is:
=($15*8hrs)*15 days = 1800
=($15*8hrs)*20 days = 2880
so the summary pay should be $4680.
 
Upvote 0
Not sure I fully understand what you're after, but how about

Worksheet Formulas
CellFormula
B10=SUMPRODUCT(--($A$2:$A$5=$A10),(B2:B5)*(C2:C5)*8)

<thead>
</thead><tbody>
</tbody>

<tbody>
</tbody>

That did the trick!! Thanks!!!!!! (y) :pray: :pray:
 
Upvote 0
Glad it worked & thanks for the feedback
 
Upvote 0
Yes, the per diem would be (and is) multiplied by the number of days on my spreadsheet. I was just typing out a simple version of it.

Yes you are correct, I added the totals on the SUMMARY table; whoops.:oops:
the pay summary is:
=($15*8hrs)*15 days = 1800
=($15*8hrs)*20 days = 2880
so the summary pay should be $4680.

Just to give you the complete set:


Book1
ABCDEF
1TypePay RateDaysHotelPer Diemtotal
2109915150502550
310991820500504380
4Internal3510200503500
5Vendor100100508500
6
7
8TypePayHotelPer DiemTotal
91099$4,6805001750$6,930
10Internal$2,800200500$3,500
11Vendor$8,0000500$8,500
Sheet368
Cell Formulas
RangeFormula
F2=B2*8*C2+D2+E2*C2
B9=SUMPRODUCT((A$2:A$5=A9)*B$2:B$5*8*C$2:C$5)
C9=SUMIFS(D$2:D$5,A$2:A$5,A9)
D9=SUMPRODUCT((A$2:A$5=A9)*E$2:E$5*C$2:C$5)
E9=SUM(B9:D9)


All formulas copied down.
 
Upvote 0

Forum statistics

Threads
1,214,622
Messages
6,120,572
Members
448,972
Latest member
Shantanu2024

We've detected that you are using an adblocker.

We have a great community of people providing Excel help here, but the hosting costs are enormous. You can help keep this site running by allowing ads on MrExcel.com.
Allow Ads at MrExcel

Which adblocker are you using?

Disable AdBlock

Follow these easy steps to disable AdBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the icon in the browser’s toolbar.
2)Click on the "Pause on this site" option.
Go back

Disable AdBlock Plus

Follow these easy steps to disable AdBlock Plus

1)Click on the icon in the browser’s toolbar.
2)Click on the toggle to disable it for "mrexcel.com".
Go back

Disable uBlock Origin

Follow these easy steps to disable uBlock Origin

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back

Disable uBlock

Follow these easy steps to disable uBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back
Back
Top