What excel formula could I use

hkese

New Member
Joined
Jun 17, 2014
Messages
15
Profit/Loss


HKDBonus 10%Bonus Payable
633,122.1563,312.2163,312.21
2,409,094.43240,909.44240,909.44
133,312.3713,331.2413,331.24
362,337.6136,233.7636,233.76
(1,945,668.04)(194,566.80)0.00
587,245.3158,724.530.00
1,769,208.71176,920.8741,078.60

<colgroup><col><col><col></colgroup><tbody>
</tbody>


Hello, I have a table as above.
I want to enter a formula into the "Bonus Payable" column so that I don't have to enter the number manually.
The amounts under Bonus Payable is calculated as follows.
If the profit is positive, then the bonus payable will simply be 10% of the profit.
If it's a loss, then there will be no bonus payable.
If next month has a profit, bonus will only be paid if 10% of it exceeds 10% of the loss incurred from previous month.
So 41,078.60 is calculated as (176,920.87 + 58,724.53 - 194,566.80) = 41,078.60.
Thanks v
 

Excel Facts

Does the VLOOKUP table have to be sorted?
No! when you are using an exact match, the VLOOKUP table can be in any order. Best-selling items at the top is actually the best.
For bonus payable for current month it is simply
Code:
=IF([HKD]>=0; [HKD]*0.1;0)
.

It's not really clear from your table which month is current, previous or next, but you can solve it with an additional IF statement
 
Upvote 0
For bonus payable for current month it is simply
Code:
=IF([HKD]>=0; [HKD]*0.1;0)
.

It's not really clear from your table which month is current, previous or next, but you can solve it with an additional IF statement

The above formula would only work until there's a loss for the month.
As you can see, in row number 6, even though there's a profit, no bonus was distributed because 10% of it (58,724.53) did not exceed the loss from the previous month (-194,566.80).
 
Upvote 0
Perhaps try...
Excel 2010
ABC
1HKDBonus 10%Bonus Payable
2 £ 633,122 £ 63,312 £ 63,312
3 £ 2,409,094 £ 240,909 £ 240,909
4 £ 133,312 £ 13,331 £ 13,331
5 £ 362,338 £ 36,234 £ 36,234
6-£ 1,945,668 -£ 194,567 £ -
7 £ 587,245 £ 58,725 £ -
8 £ 1,769,209 £ 176,921 £ 41,079

<colgroup><col><col><col><col></colgroup><thead>
</thead><tbody>
</tbody>
Sheet1

Worksheet Formulas
CellFormula
C2=MAX((SUM($A$1:A2)*0.1)-SUM($C$1:C1), 0)
C3=MAX((SUM($A$1:A3)*0.1)-SUM($C$1:C2), 0)
C4=MAX((SUM($A$1:A4)*0.1)-SUM($C$1:C3), 0)
C5=MAX((SUM($A$1:A5)*0.1)-SUM($C$1:C4), 0)
C6=MAX((SUM($A$1:A6)*0.1)-SUM($C$1:C5), 0)
C7=MAX((SUM($A$1:A7)*0.1)-SUM($C$1:C6), 0)
C8=MAX((SUM($A$1:A8)*0.1)-SUM($C$1:C7), 0)

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

<tbody>
</tbody>



/AJ
 
Upvote 0
See possible solution below:
5TtC0xJ.png


The formula is as follows:
Code:
=IF(A7>0,IF(A7+A6>=0,A7*0.1,0),0)
 
Upvote 0

Forum statistics

Threads
1,213,544
Messages
6,114,239
Members
448,555
Latest member
RobertJones1986

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