Rounding shares to whole numbers

dannyt41

Board Regular
Joined
Jul 20, 2014
Messages
86
Hi everyone,

This is potentially more of a math question, but I'm hoping there is an excel formula that could also help.

I'm trying to divide a number of shares by percentages with 14 decimals. The end number of shares needs to be a whole number, however whenever I round I am always left with a remainder. Example -




The example above gives a difference of 3. What is the best way to approach this type of rounding? Is there a formula I can use to ensure the rounded total is 33,557?

Many thanks,
Daniel
 

Excel Facts

Create a Pivot Table on a Map
If your data has zip codes, postal codes, or city names, select the data and use Insert, 3D Map. (Found to right of chart icons).
My approach is as follows. But I think shg has a different approach that randomizes the off-by-one errors, which are unavoidable. I never can remember his approach.

Caveat: Because I was unable to copy-and-paste from your posted image, my percentages and prorated share amounts differ slightly from yours. However, the results are close.

[TABLE="class: grid, width: 500"]
<tbody>[TR]
[TH][/TH]
[TH]A
[/TH]
[TH]B
[/TH]
[TH]C
[/TH]
[TH]D
[/TH]
[/TR]
[TR]
[TD="align: center"]1
[/TD]
[TD="align: right"]Total Shares
[/TD]
[TD="align: right"]33557
[/TD]
[TD="align: right"][/TD]
[TD="align: right"][/TD]
[/TR]
[TR]
[TD="align: center"]2
[/TD]
[TD="align: right"][/TD]
[TD="align: right"][/TD]
[TD="align: right"][/TD]
[TD="align: right"][/TD]
[/TR]
[TR]
[TD="align: center"]3
[/TD]
[TD="align: right"]
Percentage

[/TD]
[TD="align: right"]Prorated
Shares

[/TD]
[TD="align: right"]
Round

[/TD]
[TD="align: right"]Cuml
Round

[/TD]
[/TR]
[TR]
[TD="align: center"]4
[/TD]
[TD="align: right"]4.95849212790250%
[/TD]
[TD="align: right"]1663.921203360240
[/TD]
[TD="align: right"]1664
[/TD]
[TD="align: right"]1664
[/TD]
[/TR]
[TR]
[TD="align: center"]5
[/TD]
[TD="align: right"]3.30567304246942%
[/TD]
[TD="align: right"]1109.284702861460
[/TD]
[TD="align: right"]1109
[/TD]
[TD="align: right"]1109
[/TD]
[/TR]
[TR]
[TD="align: center"]6
[/TD]
[TD="align: right"]6.61133625561081%
[/TD]
[TD="align: right"]2218.566107295320
[/TD]
[TD="align: right"]2219
[/TD]
[TD="align: right"]2219
[/TD]
[/TR]
[TR]
[TD="align: center"]7
[/TD]
[TD="align: right"]6.61134204650717%
[/TD]
[TD="align: right"]2218.568050546410
[/TD]
[TD="align: right"]2219
[/TD]
[TD="align: right"]2218
[/TD]
[/TR]
[TR]
[TD="align: center"]8
[/TD]
[TD="align: right"]2.47926594092860%
[/TD]
[TD="align: right"]831.967271797410
[/TD]
[TD="align: right"]832
[/TD]
[TD="align: right"]832
[/TD]
[/TR]
[TR]
[TD="align: center"]9
[/TD]
[TD="align: right"]9.91699622035434%
[/TD]
[TD="align: right"]3327.846421664310
[/TD]
[TD="align: right"]3328
[/TD]
[TD="align: right"]3328
[/TD]
[/TR]
[TR]
[TD="align: center"]10
[/TD]
[TD="align: right"]6.61346292107559%
[/TD]
[TD="align: right"]2219.279752425330
[/TD]
[TD="align: right"]2219
[/TD]
[TD="align: right"]2219
[/TD]
[/TR]
[TR]
[TD="align: center"]11
[/TD]
[TD="align: right"]1.65283419699388%
[/TD]
[TD="align: right"]554.641571485235
[/TD]
[TD="align: right"]555
[/TD]
[TD="align: right"]555
[/TD]
[/TR]
[TR]
[TD="align: center"]12
[/TD]
[TD="align: right"]1.65308763318103%
[/TD]
[TD="align: right"]554.726617066559
[/TD]
[TD="align: right"]555
[/TD]
[TD="align: right"]555
[/TD]
[/TR]
[TR]
[TD="align: center"]13
[/TD]
[TD="align: right"]1.65284313954456%
[/TD]
[TD="align: right"]554.644572336969
[/TD]
[TD="align: right"]555
[/TD]
[TD="align: right"]554
[/TD]
[/TR]
[TR]
[TD="align: center"]14
[/TD]
[TD="align: right"]4.95944478963657%
[/TD]
[TD="align: right"]1664.240888058340
[/TD]
[TD="align: right"]1664
[/TD]
[TD="align: right"]1665
[/TD]
[/TR]
[TR]
[TD="align: center"]15
[/TD]
[TD="align: right"]6.61133256465374%
[/TD]
[TD="align: right"]2218.564868720850
[/TD]
[TD="align: right"]2219
[/TD]
[TD="align: right"]2218
[/TD]
[/TR]
[TR]
[TD="align: center"]16
[/TD]
[TD="align: right"]1.65316589599464%
[/TD]
[TD="align: right"]554.752879718920
[/TD]
[TD="align: right"]555
[/TD]
[TD="align: right"]555
[/TD]
[/TR]
[TR]
[TD="align: center"]17
[/TD]
[TD="align: right"]1.32227119770626%
[/TD]
[TD="align: right"]443.714545814291
[/TD]
[TD="align: right"]444
[/TD]
[TD="align: right"]444
[/TD]
[/TR]
[TR]
[TD="align: center"]18
[/TD]
[TD="align: right"]1.98337237546647%
[/TD]
[TD="align: right"]665.560268035282
[/TD]
[TD="align: right"]666
[/TD]
[TD="align: right"]665
[/TD]
[/TR]
[TR]
[TD="align: center"]19
[/TD]
[TD="align: right"]0.82644310004856%
[/TD]
[TD="align: right"]277.329511083295
[/TD]
[TD="align: right"]277
[/TD]
[TD="align: right"]278
[/TD]
[/TR]
[TR]
[TD="align: center"]20
[/TD]
[TD="align: right"]23.13963399287930%
[/TD]
[TD="align: right"]7764.966978990490
[/TD]
[TD="align: right"]7765
[/TD]
[TD="align: right"]7765
[/TD]
[/TR]
[TR]
[TD="align: center"]21
[/TD]
[TD="align: right"]9.91700597806600%
[/TD]
[TD="align: right"]3327.849696059610
[/TD]
[TD="align: right"]3328
[/TD]
[TD="align: right"]3327
[/TD]
[/TR]
[TR]
[TD="align: center"]22
[/TD]
[TD="align: right"]4.13199658098062%
[/TD]
[TD="align: right"]1386.574092679660
[/TD]
[TD="align: right"]1387
[/TD]
[TD="align: right"]1387
[/TD]
[/TR]
[TR]
[TD="align: center"]23
[/TD]
[TD="align: right"][/TD]
[TD="align: right"][/TD]
[TD="align: right"][/TD]
[TD="align: right"][/TD]
[/TR]
[TR]
[TD="align: center"]24
[/TD]
[TD="align: right"]100.00000000000000%
[/TD]
[TD="align: right"]33557.000000000000
[/TD]
[TD="align: right"]33560
[/TD]
[TD="align: right"]33557
[/TD]
[/TR]
</tbody>[/TABLE]

Code:
Formulas:
D4:  =ROUND(A4*B1,0)
D5:  =ROUND(SUM($A$4:A5)*$B$1 - SUM($D$4:D4), 0)

Copy D5 into D6:D22
 
Last edited:
Upvote 0
My approach is as follows. But I think shg has a different approach that randomizes the off-by-one errors, which are unavoidable. I never can remember his approach.

Caveat: Because I was unable to copy-and-paste from your posted image, my percentages and prorated share amounts differ slightly from yours. However, the results are close.

[TABLE="class: grid, width: 500"]
<tbody>[TR]
[TH][/TH]
[TH]A[/TH]
[TH]B[/TH]
[TH]C[/TH]
[TH]D[/TH]
[/TR]
[TR]
[TD="align: center"]1[/TD]
[TD="align: right"]Total Shares[/TD]
[TD="align: right"]33557[/TD]
[TD="align: right"][/TD]
[TD="align: right"][/TD]
[/TR]
[TR]
[TD="align: center"]2[/TD]
[TD="align: right"][/TD]
[TD="align: right"][/TD]
[TD="align: right"][/TD]
[TD="align: right"][/TD]
[/TR]
[TR]
[TD="align: center"]3[/TD]
[TD="align: right"]
Percentage
[/TD]
[TD="align: right"]Prorated
Shares
[/TD]
[TD="align: right"]
Round
[/TD]
[TD="align: right"]Cuml
Round
[/TD]
[/TR]
[TR]
[TD="align: center"]4[/TD]
[TD="align: right"]4.95849212790250%[/TD]
[TD="align: right"]1663.921203360240[/TD]
[TD="align: right"]1664[/TD]
[TD="align: right"]1664[/TD]
[/TR]
[TR]
[TD="align: center"]5[/TD]
[TD="align: right"]3.30567304246942%[/TD]
[TD="align: right"]1109.284702861460[/TD]
[TD="align: right"]1109[/TD]
[TD="align: right"]1109[/TD]
[/TR]
[TR]
[TD="align: center"]6[/TD]
[TD="align: right"]6.61133625561081%[/TD]
[TD="align: right"]2218.566107295320[/TD]
[TD="align: right"]2219[/TD]
[TD="align: right"]2219[/TD]
[/TR]
[TR]
[TD="align: center"]7[/TD]
[TD="align: right"]6.61134204650717%[/TD]
[TD="align: right"]2218.568050546410[/TD]
[TD="align: right"]2219[/TD]
[TD="align: right"]2218[/TD]
[/TR]
[TR]
[TD="align: center"]8[/TD]
[TD="align: right"]2.47926594092860%[/TD]
[TD="align: right"]831.967271797410[/TD]
[TD="align: right"]832[/TD]
[TD="align: right"]832[/TD]
[/TR]
[TR]
[TD="align: center"]9[/TD]
[TD="align: right"]9.91699622035434%[/TD]
[TD="align: right"]3327.846421664310[/TD]
[TD="align: right"]3328[/TD]
[TD="align: right"]3328[/TD]
[/TR]
[TR]
[TD="align: center"]10[/TD]
[TD="align: right"]6.61346292107559%[/TD]
[TD="align: right"]2219.279752425330[/TD]
[TD="align: right"]2219[/TD]
[TD="align: right"]2219[/TD]
[/TR]
[TR]
[TD="align: center"]11[/TD]
[TD="align: right"]1.65283419699388%[/TD]
[TD="align: right"]554.641571485235[/TD]
[TD="align: right"]555[/TD]
[TD="align: right"]555[/TD]
[/TR]
[TR]
[TD="align: center"]12[/TD]
[TD="align: right"]1.65308763318103%[/TD]
[TD="align: right"]554.726617066559[/TD]
[TD="align: right"]555[/TD]
[TD="align: right"]555[/TD]
[/TR]
[TR]
[TD="align: center"]13[/TD]
[TD="align: right"]1.65284313954456%[/TD]
[TD="align: right"]554.644572336969[/TD]
[TD="align: right"]555[/TD]
[TD="align: right"]554[/TD]
[/TR]
[TR]
[TD="align: center"]14[/TD]
[TD="align: right"]4.95944478963657%[/TD]
[TD="align: right"]1664.240888058340[/TD]
[TD="align: right"]1664[/TD]
[TD="align: right"]1665[/TD]
[/TR]
[TR]
[TD="align: center"]15[/TD]
[TD="align: right"]6.61133256465374%[/TD]
[TD="align: right"]2218.564868720850[/TD]
[TD="align: right"]2219[/TD]
[TD="align: right"]2218[/TD]
[/TR]
[TR]
[TD="align: center"]16[/TD]
[TD="align: right"]1.65316589599464%[/TD]
[TD="align: right"]554.752879718920[/TD]
[TD="align: right"]555[/TD]
[TD="align: right"]555[/TD]
[/TR]
[TR]
[TD="align: center"]17[/TD]
[TD="align: right"]1.32227119770626%[/TD]
[TD="align: right"]443.714545814291[/TD]
[TD="align: right"]444[/TD]
[TD="align: right"]444[/TD]
[/TR]
[TR]
[TD="align: center"]18[/TD]
[TD="align: right"]1.98337237546647%[/TD]
[TD="align: right"]665.560268035282[/TD]
[TD="align: right"]666[/TD]
[TD="align: right"]665[/TD]
[/TR]
[TR]
[TD="align: center"]19[/TD]
[TD="align: right"]0.82644310004856%[/TD]
[TD="align: right"]277.329511083295[/TD]
[TD="align: right"]277[/TD]
[TD="align: right"]278[/TD]
[/TR]
[TR]
[TD="align: center"]20[/TD]
[TD="align: right"]23.13963399287930%[/TD]
[TD="align: right"]7764.966978990490[/TD]
[TD="align: right"]7765[/TD]
[TD="align: right"]7765[/TD]
[/TR]
[TR]
[TD="align: center"]21[/TD]
[TD="align: right"]9.91700597806600%[/TD]
[TD="align: right"]3327.849696059610[/TD]
[TD="align: right"]3328[/TD]
[TD="align: right"]3327[/TD]
[/TR]
[TR]
[TD="align: center"]22[/TD]
[TD="align: right"]4.13199658098062%[/TD]
[TD="align: right"]1386.574092679660[/TD]
[TD="align: right"]1387[/TD]
[TD="align: right"]1387[/TD]
[/TR]
[TR]
[TD="align: center"]23[/TD]
[TD="align: right"][/TD]
[TD="align: right"][/TD]
[TD="align: right"][/TD]
[TD="align: right"][/TD]
[/TR]
[TR]
[TD="align: center"]24[/TD]
[TD="align: right"]100.00000000000000%[/TD]
[TD="align: right"]33557.000000000000[/TD]
[TD="align: right"]33560[/TD]
[TD="align: right"]33557[/TD]
[/TR]
</tbody>[/TABLE]

Code:
Formulas:
D4:  =ROUND(A4*B1,0)
D5:  =ROUND(SUM($A$4:A5)*$B$1 - SUM($D$4:D4), 0)

Copy D5 into D6:D22


Thank you very much, the formulas work great.

Is this a fairly standard rounding approach for allocating shares? I can't find many references online to this type of calculation and would like to reference something if possible!

Many thanks,
Daniel
 
Upvote 0
Is this a fairly standard rounding approach for allocating shares?

Ad hoc, I'm afraid.

I believe there is a "standard" algorithm or genereally accepted method. I'm sure I read a wiki page or other onine article long ago. But I'm having trouble finding it now.

My algorithm can be poorly behaved (or at least non-optimal). Consider this....

For my posted example, several rows round in the opposite direction: row 7, 13, 15, 18 and 21 round down; and row 14 and 19 round up. The sum of squared errors (SSE) is about 4.03.

In contrast, the SSE is lower, about 2.17, if we force only row 6, 15 and 18 to round down, the opposite direction.
 
Upvote 0
Another way:

[Table="width:, class:grid"][tr][td="bgcolor:#C0C0C0"][/td][td="bgcolor:#C0C0C0"]
A​
[/td][td="bgcolor:#C0C0C0"]
B​
[/td][td="bgcolor:#C0C0C0"]
C​
[/td][/tr][tr][td="bgcolor:#C0C0C0"]
1​
[/td][td="bgcolor:#F3F3F3"]
Total Shares
[/td][td]
33557​
[/td][td="bgcolor:#F3F3F3"]
[/td][/tr]
[tr][td="bgcolor:#C0C0C0"]
2​
[/td][td][/td][td][/td][td][/td][/tr]
[tr][td="bgcolor:#C0C0C0"]
3​
[/td][td="bgcolor:#F3F3F3"]
Pct
[/td][td="bgcolor:#F3F3F3"]
Shares
[/td][td][/td][/tr]
[tr][td="bgcolor:#C0C0C0"]
4​
[/td][td]
4.95849212790250%​
[/td][td="bgcolor:#E5E5E5"]
1664​
[/td][td]B4: =ROUND(A4 / (A$24 - SUM(A$3:A3)) * (B$1 - SUM(B$3:B3)), 0)[/td][/tr]
[tr][td="bgcolor:#C0C0C0"]
5​
[/td][td]
3.30567304246942%​
[/td][td="bgcolor:#E5E5E5"]
1109​
[/td][td][/td][/tr]
[tr][td="bgcolor:#C0C0C0"]
6​
[/td][td]
6.61133625561081%​
[/td][td="bgcolor:#E5E5E5"]
2219​
[/td][td][/td][/tr]
[tr][td="bgcolor:#C0C0C0"]
7​
[/td][td]
6.61134204650717%​
[/td][td="bgcolor:#E5E5E5"]
2219​
[/td][td][/td][/tr]
[tr][td="bgcolor:#C0C0C0"]
8​
[/td][td]
2.47926594092860%​
[/td][td="bgcolor:#E5E5E5"]
832​
[/td][td][/td][/tr]
[tr][td="bgcolor:#C0C0C0"]
9​
[/td][td]
9.91699622035434%​
[/td][td="bgcolor:#E5E5E5"]
3328​
[/td][td][/td][/tr]
[tr][td="bgcolor:#C0C0C0"]
10​
[/td][td]
6.61346292107559%​
[/td][td="bgcolor:#E5E5E5"]
2219​
[/td][td][/td][/tr]
[tr][td="bgcolor:#C0C0C0"]
11​
[/td][td]
1.65283419699388%​
[/td][td="bgcolor:#E5E5E5"]
555​
[/td][td][/td][/tr]
[tr][td="bgcolor:#C0C0C0"]
12​
[/td][td]
1.65308763318103%​
[/td][td="bgcolor:#E5E5E5"]
555​
[/td][td][/td][/tr]
[tr][td="bgcolor:#C0C0C0"]
13​
[/td][td]
1.65284313954456%​
[/td][td="bgcolor:#E5E5E5"]
555​
[/td][td][/td][/tr]
[tr][td="bgcolor:#C0C0C0"]
14​
[/td][td]
4.95944478963657%​
[/td][td="bgcolor:#E5E5E5"]
1664​
[/td][td][/td][/tr]
[tr][td="bgcolor:#C0C0C0"]
15​
[/td][td]
6.61133256465374%​
[/td][td="bgcolor:#E5E5E5"]
2218​
[/td][td][/td][/tr]
[tr][td="bgcolor:#C0C0C0"]
16​
[/td][td]
1.65316589599464%​
[/td][td="bgcolor:#E5E5E5"]
555​
[/td][td][/td][/tr]
[tr][td="bgcolor:#C0C0C0"]
17​
[/td][td]
1.32227119770626%​
[/td][td="bgcolor:#E5E5E5"]
444​
[/td][td][/td][/tr]
[tr][td="bgcolor:#C0C0C0"]
18​
[/td][td]
1.98337237546647%​
[/td][td="bgcolor:#E5E5E5"]
665​
[/td][td][/td][/tr]
[tr][td="bgcolor:#C0C0C0"]
19​
[/td][td]
0.82644310004856%​
[/td][td="bgcolor:#E5E5E5"]
277​
[/td][td][/td][/tr]
[tr][td="bgcolor:#C0C0C0"]
20​
[/td][td]
23.13963399287930%​
[/td][td="bgcolor:#E5E5E5"]
7765​
[/td][td][/td][/tr]
[tr][td="bgcolor:#C0C0C0"]
21​
[/td][td]
9.91700597806600%​
[/td][td="bgcolor:#E5E5E5"]
3328​
[/td][td][/td][/tr]
[tr][td="bgcolor:#C0C0C0"]
22​
[/td][td]
4.13199658098062%​
[/td][td="bgcolor:#E5E5E5"]
1386​
[/td][td][/td][/tr]
[tr][td="bgcolor:#C0C0C0"]
23​
[/td][td][/td][td="bgcolor:#E5E5E5"][/td][td][/td][/tr]
[tr][td="bgcolor:#C0C0C0"]
24​
[/td][td="bgcolor:#E5E5E5"]
100.00000000000000%
[/td][td="bgcolor:#E5E5E5"]
33557
[/td][td][/td][/tr]
[/table]
 
Upvote 0

Forum statistics

Threads
1,223,893
Messages
6,175,240
Members
452,621
Latest member
Laura_PinksBTHFT

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