How do I take a total value and reduce the value of a cell and move to next until the total is met?

Knockoutpie

Board Regular
Joined
Sep 10, 2018
Messages
116
Office Version
  1. 365
Platform
  1. Windows
It's difficult to describe, but could be considered something like a first in first out calculator.

There must be an easier way to do this than manual subtraction.

For this example the total inventory is 7500, I Would like to find how much was under 25, and if the total isn't met then move to next column under 10, etc using the next cell until the total inventory is met.

Example
Item#Total Inventory251050
Part Example750071501800760032950

<tbody>
</tbody>

Final Result
Item#Total Inventory251050
Part Example7500715035000

<tbody>
</tbody>
 

Excel Facts

Format cells as time
Select range and press Ctrl+Shift+2 to format cells as time. (Shift 2 is the @ sign).
Maybe something like this:


Book1
ABCDEF
1Item#Total Inventory251050
2Part Example750071501800760032950
3
4Final Result
5Item#Total Inventory251050
6Part Example7500715035000
Sheet6
Cell Formulas
RangeFormula
C6=MIN(C2,2*$B6-SUM($B6:B6))


Put the C6 formula in and drag to the right.
 
Upvote 0
Maybe something like this:

ABCDEF
1Item#Total Inventory251050
2Part Example750071501800760032950
3
4Final Result
5Item#Total Inventory251050
6Part Example7500715035000

<tbody>
</tbody>
Sheet6

Worksheet Formulas
CellFormula
C6=MIN(C2,2*$B6-SUM($B6:B6))

<tbody>
</tbody>

<tbody>
</tbody>



Put the C6 formula in and drag to the right.

Hi Eric,


It looks like your formula is reference both my example and what i'd like the outcome to be.

In this case the formula would have to be something along the lines of =MIN(B2,2*$B2-SUM($B2:F2)) (everything in row 2)

The result of this formula is not correct. But this is the correct path I would like to take.
 
Last edited:
Upvote 0
This is why I said "maybe something like this". I'm not entirely sure what your layout is like. Based on what you posted, it appeared that the top grid showed how many items were in each "bucket". Then the next grid showed an individual result.

However, it seems like you meant that the 2 grids referred to the same range, but you wanted that range to turn into what the second grid looks like. If that's the case, you might be looking more at a VBA solution. Possibly a macro that looks at your parts sheet and adjusts all of them as desired.

If that's the case, let me know.
 
Upvote 0
This is why I said "maybe something like this". I'm not entirely sure what your layout is like. Based on what you posted, it appeared that the top grid showed how many items were in each "bucket". Then the next grid showed an individual result.

However, it seems like you meant that the 2 grids referred to the same range, but you wanted that range to turn into what the second grid looks like. If that's the case, you might be looking more at a VBA solution. Possibly a macro that looks at your parts sheet and adjusts all of them as desired.

If that's the case, let me know.

Hey Eric,

Both tables are referring to the same range.

VBA solution would be perfectly fine with me. :) I appreciate your assistance.
 
Upvote 0
Open a COPY of your workbook. I assume a starting range like this:


Book1
ABCDEF
1Item#Total Inventory251050
2Part Example750071501800760032950
3Example 250004000400300800
4Example 3600030002000500400
Sheet4


Now press Alt-F11 to open the VBA editor. Press Alt-IM to insert a module. Paste the following code into the window that opens:

Code:
Sub CalcInventory()


    For r = 2 To Cells(Rows.Count, "B").End(xlUp).Row
        amt = Cells(r, "B")
        For c = 3 To 6
            inv = Cells(r, c)
            m = IIf(amt < inv, amt, inv)
            Cells(r, c) = m
            amt = amt - m
        Next c
        If amt > 0 Then Cells(r, "G") = "Extra: " & amt
    Next r
    
End Sub
Press Alt-Q to exit the editor. Now on your inventory sheet press Alt-F8. Select CalcInventory and press Run. You should end up with:


Book1
ABCDEFG
1Item#Total Inventory251050
2Part Example7500715035000
3Example 250004000400300300
4Example 3600030002000500400Extra: 100
Sheet4


Let us know if this is what you want.
 
Upvote 0

Forum statistics

Threads
1,214,565
Messages
6,120,254
Members
448,952
Latest member
kjurney

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