For the future, please try to provide your sample data in a form we can copy/paste as many helpers will just bypass your question if they have to manually type it out.
My signature block below has more help on that.
For the layout you provided in your sample, try this code in a
copy of your workbook.
Code:
Sub DistributeNegativeValues()
Dim AL As Object
Dim a As Variant, itm As Variant
Dim Dist As Long, i As Long, uba As Long
Set AL = CreateObject("System.Collections.ArrayList")
a = Range("B1", Range("B" & Rows.Count).End(xlUp)).Value
uba = UBound(a)
For Each itm In a
If itm < 0 Then
Dist = Dist - itm
Else
AL.Add itm
End If
Next itm
AL.Sort
AL.Reverse
ReDim Preserve a(1 To uba, 1 To 2)
For Each itm In AL
For i = 1 To uba
If a(i, 1) = itm Then
a(i, 2) = a(i, 1)
If a(i, 2) > Dist Then a(i, 2) = Dist
Dist = Dist - a(i, 2)
End If
Next i
Next itm
With Range("C1").Resize(uba)
.Value = Application.Index(a, 0, 2)
On Error Resume Next
.SpecialCells(xlBlanks).Value = 0
On Error GoTo 0
End With
End Sub
Here is my worksheet. Original data in A:B, result of code in column C
Excel 2016
<colgroup><col style="width: 25pxpx"><col><col><col></colgroup><thead>
</thead><tbody>
[TD="align: center"]1[/TD]
[TD="align: right"]1[/TD]
[TD="align: right"]10[/TD]
[TD="align: right"]10[/TD]
[TD="align: center"]2[/TD]
[TD="align: right"]2[/TD]
[TD="align: right"]-15[/TD]
[TD="align: right"]0[/TD]
[TD="align: center"]3[/TD]
[TD="align: right"]3[/TD]
[TD="align: right"]45[/TD]
[TD="align: right"]45[/TD]
[TD="align: center"]4[/TD]
[TD="align: right"]4[/TD]
[TD="align: right"]5[/TD]
[TD="align: right"]0[/TD]
[TD="align: center"]5[/TD]
[TD="align: right"]5[/TD]
[TD="align: right"]6[/TD]
[TD="align: right"]5[/TD]
[TD="align: center"]6[/TD]
[TD="align: right"]6[/TD]
[TD="align: right"]-45[/TD]
[TD="align: right"]0[/TD]
</tbody>
Distribute