+ Reply to Thread
Results 1 to 9 of 9

Challenging Formula Cumulative sum up to a number

  1. #1
    Registered User
    Join Date
    09-28-2009
    Location
    usa
    MS-Off Ver
    Excel 2003
    Posts
    8

    Challenging Formula Cumulative sum up to a number

    I have an spreasheet that i am trying to create. Overall I have established quantities per item and I need a formula that will tell me how many pieces of the Item I should pick per line, Ex
    Item A: 13 Pieces
    Item B: 2 Pieces,

    Inventory
    Line 1 item a: 5 pcs
    Line 2 Item a: 5 pcs
    Line 3 Item a: 5 pcs
    Line 4 item a: 5 pcs
    Line 5: item b: 3 pcs

    Basically the result for the formula i am looking for will tell me the items to be picked until budget is reached. line 1: 5 pcs, line 2: 5 pcs and line 3: 3 pcs. Line 4 should say: 0 pcs (budget already met), line 5:3 pieces.

    I tried using a cumulative formula and if statement but did not work. any suggestions???

    Thanks.

  2. #2
    Forum Expert newdoverman's Avatar
    Join Date
    02-07-2013
    Location
    Port Dover, Ontario, Canada
    MS-Off Ver
    2010
    Posts
    10,330

    Re: Challenging Formula Cumulative sum up to a number

    Attach a sample workbook. Make sure there is just enough data to demonstrate your need. Include a BEFORE sheet and an AFTER sheet in the workbook if needed to show the process you're trying to complete or automate. Make sure your desired results are shown, mock them up manually if necessary.

    Remember to desensitize the data.

    Click on GO ADVANCED and use the paperclip icon to open the upload window.

    View Pic
    <---------If you like someone's answer, click the star to the left of one of their posts to give them a reputation point for that answer.
    Ron W

  3. #3
    Registered User
    Join Date
    09-28-2009
    Location
    usa
    MS-Off Ver
    Excel 2003
    Posts
    8

    Re: Challenging Formula Cumulative sum up to a number

    Sample report.xls File attached

    It seems very simple enough but for some reason i find it challenging
    Last edited by crisaldana; 06-16-2014 at 07:45 PM. Reason: none to be honest

  4. #4
    Administrator FDibbins's Avatar
    Join Date
    12-29-2011
    Location
    Duncansville, PA USA
    MS-Off Ver
    Excel 7/10/13/16/365 (PC ver 2310)
    Posts
    52,917

    Re: Challenging Formula Cumulative sum up to a number

    Try this, copied down...
    =IF(D4=$A$4,IF(SUMIF($D$4:D4,$A$4,$F$4:F4)<$B$4,"",$B$4&" Units Reached"),IF(SUMIF($D$4:D4,$A$5,$F$4:F4)<$B$5,"",$B$5&" Units Reached"))
    1. Use code tags for VBA. [code] Your Code [/code] (or use the # button)
    2. If your question is resolved, mark it SOLVED using the thread tools
    3. Click on the star if you think someone helped you

    Regards
    Ford

  5. #5
    Registered User
    Join Date
    09-28-2009
    Location
    usa
    MS-Off Ver
    Excel 2003
    Posts
    8

    Re: Challenging Formula Cumulative sum up to a number

    Thank you for your assistance. however The part i need assistance with column F, in which the quantities to be picked will be
    Sample report.xlsshown.

  6. #6
    Administrator FDibbins's Avatar
    Join Date
    12-29-2011
    Location
    Duncansville, PA USA
    MS-Off Ver
    Excel 7/10/13/16/365 (PC ver 2310)
    Posts
    52,917

    Re: Challenging Formula Cumulative sum up to a number

    oh OK, that makes it a bit simpler...
    =IF(D4=$A$4,IF(SUMIF($D$4:D4,$A$4,$F$4:F4)<=$B$4,F4,$B$4),IF(SUMIF($D$4:D4,$A$5,$F$4:F4)<=$B$5,F4,$B$5))

  7. #7
    Forum Expert
    Join Date
    08-12-2012
    Location
    Sydney, Australia
    MS-Off Ver
    Excel 2010
    Posts
    5,636

    Re: Challenging Formula Cumulative sum up to a number

    how about this?

    made some slight amendment with addressing ($) to the formula so you can move it to column F

    Formula: copy to clipboard
    Please Login or Register  to view this content.
    Attached Files Attached Files
    Last edited by humdingaling; 06-16-2014 at 09:19 PM. Reason: formula adjust
    If you are satisfied with the solution(s) provided, please mark your thread as Solved.
    Select Thread Tools-> Mark thread as Solved. To undo, select Thread Tools-> Mark thread as Unsolved.

  8. #8
    Forum Guru benishiryo's Avatar
    Join Date
    03-25-2011
    Location
    Singapore
    MS-Off Ver
    Excel 2013
    Posts
    5,147

    Re: Challenging Formula Cumulative sum up to a number

    hi there. another way:
    =MIN(E4,MAX(VLOOKUP(D4,A:B,2,0)-SUMIF(D$3:D3,D4,E$3:E3),0))

    Thanks, if you have clicked on the * and added our rep.

    If you're satisfied with the answer, click Thread Tools above your first post, select "Mark your thread as Solved".

    "Contentment is not the fulfillment of what you want, but the realization of what you already have."


    Tips & Tutorials I Compiled | How to Get Quick & Good Answers

  9. #9
    Registered User
    Join Date
    09-28-2009
    Location
    usa
    MS-Off Ver
    Excel 2003
    Posts
    8

    Re: Challenging Formula Cumulative sum up to a number

    It worked!!! Thank you very much!!

+ Reply to Thread

Thread Information

Users Browsing this Thread

There are currently 1 users browsing this thread. (0 members and 1 guests)

Similar Threads

  1. Help with challenging array formula
    By chuji in forum Excel Formulas & Functions
    Replies: 1
    Last Post: 06-22-2013, 02:11 AM
  2. Replies: 1
    Last Post: 08-24-2010, 07:12 AM
  3. Need Help with a challenging formula.
    By gamiensrule in forum Excel Formulas & Functions
    Replies: 2
    Last Post: 07-16-2010, 10:05 PM
  4. [SOLVED] Challenging Formula
    By Gordon in forum Excel Programming / VBA / Macros
    Replies: 7
    Last Post: 06-23-2006, 04:30 PM
  5. Answers needed for challenging formula
    By Sum Limit and marking in forum Excel Formulas & Functions
    Replies: 16
    Last Post: 04-17-2006, 07:20 AM

Bookmarks

Posting Permissions

  • You may not post new threads
  • You may not post replies
  • You may not post attachments
  • You may not edit your posts

Search Engine Friendly URLs by vBSEO 3.6.0 RC 1