What formula is able to solve my inventory management

iMailMan

New Member
Joined
Sep 6, 2018
Messages
12
Before withdraw on inventory monitoring page:
[TABLE="class: grid, width: 300, align: center"]
<tbody>[TR]
[TD="align: center"]A[/TD]
[TD="align: center"]B[/TD]
[TD="align: center"]C[/TD]
[TD="align: center"]D[/TD]
[/TR]
[TR]
[TD="align: center"]1[/TD]
[TD="align: center"]Part Number[/TD]
[TD="align: center"]Start Stock Qty[/TD]
[TD="align: center"]In Stock Balance[/TD]
[/TR]
[TR]
[TD="align: center"]2[/TD]
[TD="align: center"]123[/TD]
[TD="align: center"]10[/TD]
[TD="align: center"]8[/TD]
[/TR]
[TR]
[TD="align: center"]3[/TD]
[TD="align: center"]456[/TD]
[TD="align: center"]20[/TD]
[TD="align: center"]7[/TD]
[/TR]
[TR]
[TD="align: center"]4[/TD]
[TD="align: center"]789[/TD]
[TD="align: center"]30[/TD]
[TD="align: center"]6[/TD]
[/TR]
[TR]
[TD="align: center"]5[/TD]
[TD="align: center"]101[/TD]
[TD="align: center"]40[/TD]
[TD="align: center"]5[/TD]
[/TR]
</tbody>[/TABLE]


Withdrawing on inventory withdrawal page(different tab):

[TABLE="class: grid, width: 400, align: center"]
<tbody>[TR]
[TD="align: center"]A[/TD]
[TD="align: center"]B[/TD]
[TD="align: center"]C[/TD]
[TD="align: center"]D[/TD]
[TD="align: center"]E[/TD]
[/TR]
[TR]
[TD="align: center"]1[/TD]
[TD="align: center"]Date Withdraw[/TD]
[TD="align: center"]Part Number[/TD]
[TD="align: center"]Withdraw Qty[/TD]
[TD="align: center"]In Stock Balance[/TD]
[/TR]
[TR]
[TD="align: center"]2[/TD]
[TD="align: center"]05 Sep[/TD]
[TD="align: center"]123[/TD]
[TD="align: center"]2[/TD]
[TD="align: center"]6[/TD]
[/TR]
[TR]
[TD="align: center"]3[/TD]
[TD="align: center"]06 Sep[/TD]
[TD="align: center"]456[/TD]
[TD="align: center"]3[/TD]
[TD="align: center"]4[/TD]
[/TR]
[TR]
[TD="align: center"]4[/TD]
[TD="align: center"]07 Sep[/TD]
[TD="align: center"]123[/TD]
[TD="align: center"]1[/TD]
[TD="align: center"]5[/TD]
[/TR]
</tbody>[/TABLE]

What formula should use for cell E2 to E4?

After withdraw on inventory monitoring page:
[TABLE="class: grid, width: 300, align: center"]
<tbody>[TR]
[TD="align: center"]A[/TD]
[TD="align: center"]B[/TD]
[TD="align: center"]C[/TD]
[TD="align: center"]D[/TD]
[/TR]
[TR]
[TD="align: center"]1[/TD]
[TD="align: center"]Part Number[/TD]
[TD="align: center"]Start Stock Qty[/TD]
[TD="align: center"]In Stock Qty[/TD]
[/TR]
[TR]
[TD="align: center"]2[/TD]
[TD="align: center"]123[/TD]
[TD="align: center"]10[/TD]
[TD="align: center"]5[/TD]
[/TR]
[TR]
[TD="align: center"]3[/TD]
[TD="align: center"]456[/TD]
[TD="align: center"]20[/TD]
[TD="align: center"]4[/TD]
[/TR]
[TR]
[TD="align: center"]4[/TD]
[TD="align: center"]789[/TD]
[TD="align: center"]30[/TD]
[TD="align: center"]6[/TD]
[/TR]
[TR]
[TD="align: center"]5[/TD]
[TD="align: center"]101[/TD]
[TD="align: center"]40[/TD]
[TD="align: center"]5[/TD]
[/TR]
</tbody>[/TABLE]

What formula should use for cell D2 to D5?

I already crack my head how to link and share the in stock balance as above different tab shown.
Please help and educate me.


Thanks.
 

Excel Facts

How to fill five years of quarters?
Type 1Q-2023 in a cell. Grab the fill handle and drag down or right. After 4Q-2023, Excel will jump to 1Q-2024. Dash can be any character.
Hi Mailman,

Maybe this will work for you. Drag the formula down on the Inventory tab. I recommend converting the Withdrawals ledger into a table so then as you add lines it will automatically update your inventory formula range;



Book1
ABCD
1Part NumberStart Stock QtyStocktake CountWithdrawals
21231083
34562076
47893062
51014051
Inventory
Cell Formulas
RangeFormula
D2=SUMPRODUCT((Table1[Part Number]=Inventory!A2)*Table1[Withdraw Qty])



Book1
ABCD
1Date WithdrawPart NumberWithdraw QtyIn Stock Balance
205-Sep12325
306-Sep45631
407-Sep12315
508-Sep45611
609-Sep78924
710-Sep10114
811-Sep45611
912-Sep45611
Withdrawals
Cell Formulas
RangeFormula
D2=VLOOKUP(B2,Inventory!$A$2:$D$5,3,0)-VLOOKUP(B2,Inventory!$A$2:$D$5,4,0)
 
Upvote 0
Hi,

Not entirely certain I understand all your requirements, may be this:


Book1
ABCD
11Part NumberStart Stock QtyIn Stock Balance
22123105
334562015
447893029
551014031
Monitoring
Cell Formulas
RangeFormula
D2=C2-SUMIF(Withdrawal!C$2:C$8,B2,Withdrawal!D$2:D$8)



Book1
ABCDE
11Date WithdrawPart NumberWithdraw QtyIn Stock Balance
225-Sep12328
336-Sep456317
447-Sep12317
558-Sep12325
669-Sep456215
7710-Sep101931
8811-Sep789129
Withdrawal
Cell Formulas
RangeFormula
E2=SUMIF(Monitoring!B$2:B$5,C2,Monitoring!C$2:C$5)-SUMIF(C$2:C2,C2,D$2:D2)


Change/adjust cell references and Sheet Name to suit your data, formulas copied down.
 
Last edited:
Upvote 0
Dear All,

Thanks for your formula and it was work for me.
The only problem i have faced is how to combine different tab into the formula?
 
Upvote 0
List your tabs and specify what data is in each if that differs from your original query. If you have more than one tab for withdrawals then we may need to update our formula.
 
Upvote 0
Inventory Page A (Sheet 1)
[TABLE="class: grid, width: 300, align: center"]
<tbody>[TR]
[TD]A[/TD]
[TD="align: center"]B[/TD]
[TD="align: center"]C[/TD]
[TD="align: center"]D[/TD]
[/TR]
[TR]
[TD="align: center"]1[/TD]
[TD="align: center"]Part Number[/TD]
[TD="align: center"]Start Stock Qty[/TD]
[TD="align: center"]In stock Balance[/TD]
[/TR]
[TR]
[TD]2[/TD]
[TD="align: center"]A123[/TD]
[TD="align: center"]10[/TD]
[TD="align: center"]8[/TD]
[/TR]
[TR]
[TD="align: center"]3[/TD]
[TD="align: center"]A456[/TD]
[TD="align: center"]20[/TD]
[TD="align: center"]7[/TD]
[/TR]
[TR]
[TD="align: center"]4[/TD]
[TD="align: center"]A789[/TD]
[TD="align: center"]30[/TD]
[TD="align: center"]6[/TD]
[/TR]
[TR]
[TD="align: center"]5[/TD]
[TD="align: center"]A101[/TD]
[TD="align: center"]40[/TD]
[TD="align: center"]5[/TD]
[/TR]
</tbody>[/TABLE]


Inventory Page B (Sheet 2)
[TABLE="class: grid, width: 300, align: center"]
<tbody>[TR]
[TD]A[/TD]
[TD="align: center"]B[/TD]
[TD="align: center"]C[/TD]
[TD="align: center"]D[/TD]
[/TR]
[TR]
[TD="align: center"]1[/TD]
[TD="align: center"]Part Number[/TD]
[TD="align: center"]Start Stock Qty[/TD]
[TD="align: center"]In Stock Balance[/TD]
[/TR]
[TR]
[TD]2[/TD]
[TD="align: center"]B123[/TD]
[TD="align: center"]10[/TD]
[TD="align: center"]8[/TD]
[/TR]
[TR]
[TD="align: center"]3[/TD]
[TD="align: center"]B456[/TD]
[TD="align: center"]20[/TD]
[TD="align: center"]7[/TD]
[/TR]
[TR]
[TD="align: center"]4[/TD]
[TD="align: center"]B789[/TD]
[TD="align: center"]30[/TD]
[TD="align: center"]6[/TD]
[/TR]
[TR]
[TD="align: center"]5[/TD]
[TD="align: center"]B101[/TD]
[TD="align: center"]40[/TD]
[TD="align: center"]5[/TD]
[/TR]
</tbody>[/TABLE]


How to combine above two inventory page at cell E2:E4 under withdrawal page (Sheet 3)?

[TABLE="class: grid, width: 300, align: center"]
<tbody>[TR]
[TD]A[/TD]
[TD="align: center"]B[/TD]
[TD="align: center"]C[/TD]
[TD="align: center"]D[/TD]
[TD="align: center"]E[/TD]
[/TR]
[TR]
[TD="align: center"]1[/TD]
[TD="align: center"]Date Withdraw[/TD]
[TD="align: center"]Part Number[/TD]
[TD="align: center"]Withdraw Qty[/TD]
[TD="align: center"]In stock Balance[/TD]
[/TR]
[TR]
[TD="align: center"]2[/TD]
[TD="align: center"]10 sep[/TD]
[TD="align: center"]A123[/TD]
[TD="align: center"]2[/TD]
[TD="align: center"]6[/TD]
[/TR]
[TR]
[TD="align: center"]3[/TD]
[TD="align: center"]11 Sep[/TD]
[TD="align: center"]B789[/TD]
[TD="align: center"]3[/TD]
[TD="align: center"]4[/TD]
[/TR]
[TR]
[TD="align: center"]4[/TD]
[TD="align: center"]12 Sep[/TD]
[TD="align: center"]A123[/TD]
[TD="align: center"]1[/TD]
[TD="align: center"]5[/TD]
[/TR]
</tbody>[/TABLE]

 
Upvote 0
Hi iMail,

You will need to extend these ranges to suit or it would be better to convert your Withdrawals table to a table so you don't have to keep expanding your formula ranges as your data increases;


Book1
ABC
1Part NumberStart Stock QtyIn stock Balance
2A123107
3A4562020
4A7893030
5A1014040
InventoryA
Cell Formulas
RangeFormula
C2=B2-SUMIF(Withdrawals!$B$2:$B$4,InventoryA!A2,Withdrawals!$C$2:$C$4)



Book1
ABC
1Part NumberStart Stock QtyIn Stock Balance
2B1231010
3B4562020
4B7893027
5B1014040
InventoryB
Cell Formulas
RangeFormula
C2=B2-SUMIF(Withdrawals!$B$2:$B$4,InventoryB!A2,Withdrawals!$C$2:$C$4)



Book1
ABCD
1Date WithdrawPart NumberWithdraw QtyIn stock Balance
210-SepA12327
311-SepB789327
412-SepA12317
Withdrawals
Cell Formulas
RangeFormula
D2=IF(SUMIF(InventoryA!$A$2:$A$5,Withdrawals!B2,InventoryA!$B$2:$B$5)>0,SUMIF(InventoryA!$A$2:$A$5,Withdrawals!B2,InventoryA!$B$2:$B$5),SUMIF(InventoryB!$A$2:$A$5,Withdrawals!B2,InventoryB!$B$2:$B$5))-SUMIFS($C$2:$C$5,$B$2:$B$5,B2)
 
Upvote 0
Just in case the screen has cut down the formula;

Code:
=IF(SUMIF(InventoryA!$A$2:$A$5,Withdrawals!B2,InventoryA!$B$2:$B$5)>0,SUMIF(InventoryA!$A$2:$A$5,Withdrawals!B2,InventoryA!$B$2:$B$5),SUMIF(InventoryB!$A$2:$A$5,Withdrawals!B2,InventoryB!$B$2:$B$5))-SUMIFS($C$2:$C$5,$B$2:$B$5,B2)
 
Upvote 0
Dear All,

Thanks for your formula and it was work for me.
The only problem i have faced is how to combine different tab into the formula?

As RasGhul's formulas in Post # 2 and my formulas in Post # 3 provide completely different results, I had No idea which of the 2 different solutions you were referring to, thus I did not respond.

Looks like RasGhul has modified my formulas for your additional requirements, I have not looked at or tested them, hope it all works out for you, if you have additional questions, please post back and be specific on How you want your results.
 
Last edited:
Upvote 0

Forum statistics

Threads
1,224,819
Messages
6,181,153
Members
453,021
Latest member
Justyna P

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