+ Reply to Thread
Results 1 to 8 of 8

Count Columns Until Value Reached

  1. #1
    Forum Contributor
    Join Date
    02-18-2014
    Location
    Seattle, WA
    MS-Off Ver
    Excel 2013
    Posts
    197

    Count Columns Until Value Reached

    In a retail environment we've got hundreds of products with an established breakeven point for each. I can establish whether one has reached breakeven by summing the row of sales data, but I want to know how quickly each product reaches that point.

    I need a formula to count the columns (months) and return the number once a given product has reached a certain value.

    One issue, is that each product has a different launch date. So I need the formula to ignore blank cells leading up to the product launch.

    In my sample data file attached, I've got four products with their breakeven number listed and several years of sales (by month).

    I've tried a lot of different formulas. A few from this forum came close, but didn't quite give me what I needed. So I'm really hoping you guys can help me here.

    Thanks!
    Attached Files Attached Files

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

    Re: Count Columns Until Value Reached

    welcome to the forum, phelbin. try this array formula in E3:
    =MATCH(TRUE,SUBTOTAL(9,OFFSET(G3,,,,COLUMN(G3:AX3)-COLUMN(G3)+1))>=C3,0)-COUNTBLANK(G3:AX3)

    ...confirmed by pressing CTRL+SHIFT+ENTER to activate the array, not just ENTER. You will know the array is active when you see curly braces { } appear around your formula. If you do not CTRL+SHIFT+ENTER you will get an error or a clearly incorrect answer. Press F2 on that cell and try again.

    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

  3. #3
    Forum Expert XOR LX's Avatar
    Join Date
    04-18-2013
    Location
    Turin, Italy
    MS-Off Ver
    Office 365
    Posts
    7,742

    Re: Count Columns Until Value Reached

    Hi and welcome to the forum!

    You don't include your desired results, and it's not clear if you want the number of months to be counted from the first non-blank cell in the range, or from Mar-05 regardless. However, assuming the former, this array formula** in E3:

    =MATCH(TRUE,MMULT((--(TRANSPOSE(COLUMN(INDEX(G3:AX3,MATCH(TRUE,G3:AX3<>"",0)):AX3))>=COLUMN(INDEX(G3:AX3,MATCH(TRUE,G3:AX3<>"",0)):AX3))),TRANSPOSE((INDEX(G3:AX3,MATCH(TRUE,G3:AX3<>"",0)):AX3)))>=C3,0)

    Copy down as required.

    Regards


    **Array formulas are not entered in the same way as 'standard' formulas. Instead of pressing just ENTER, you first hold down CTRL and SHIFT, and only then press ENTER. If you've done it correctly, you'll notice Excel puts curly brackets {} around the formula (though do not attempt to manually insert these yourself).
    Last edited by XOR LX; 03-03-2014 at 03:44 AM.
    Click * below if this answer helped

    Advanced Excel Techniques: http://excelxor.com/

  4. #4
    Forum Contributor
    Join Date
    02-18-2014
    Location
    Seattle, WA
    MS-Off Ver
    Excel 2013
    Posts
    197

    Re: Count Columns Until Value Reached

    Thanks to both of you!

    Benishiryo, it worked perfectly. I didn't know about countblank...that's a good trick.

  5. #5
    Forum Contributor
    Join Date
    02-18-2014
    Location
    Seattle, WA
    MS-Off Ver
    Excel 2013
    Posts
    197

    Re: Count Columns Until Value Reached

    I've run into a problem with the formula. Please see "Product 5" on attached spreadsheet.

    In the case that we discontinue a product, there will be blank cells on the end of the string of sales data. Can the formula account for that? At this point, it seems to ignore the blank cells up front, but it subtracts one for each blank cell on the end from the output.

    The current formula being used is: =MATCH(TRUE,SUBTOTAL(9,OFFSET(G3,,,,COLUMN(G3:AX3)-COLUMN(G3)+1))>=C3,0)-COUNTBLANK(G3:AX3)
    Attached Files Attached Files
    Last edited by phelbin; 03-03-2014 at 06:36 PM.

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

    Re: Count Columns Until Value Reached

    maybe in E9:
    =MATCH(TRUE,SUBTOTAL(9,OFFSET(G9,,,,COLUMN(G9:AX9)-COLUMN(G9)+1))>=C9,0)-MIN(IF(G9:AX9<>"",COLUMN(G9:AX9)-COLUMN(G9)+1))+1

    array still. do remember to mark the thread as Solved. thanks
    =)

  7. #7
    Forum Contributor
    Join Date
    02-18-2014
    Location
    Seattle, WA
    MS-Off Ver
    Excel 2013
    Posts
    197

    Re: Count Columns Until Value Reached

    That worked perfectly! Thanks so much.

  8. #8
    Registered User
    Join Date
    08-02-2021
    Location
    Switzerland
    MS-Off Ver
    365
    Posts
    1

    Thumbs up Re: Count Columns Until Value Reached

    Thanks for sharing this. Helped me fix a very sillier issue!

+ 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. [SOLVED] Count of cells that can be summed before a value is reached or exceeded?
    By Speshul in forum Excel Formulas & Functions
    Replies: 6
    Last Post: 05-29-2013, 03:35 PM
  2. [SOLVED] Fill down a row count until a new value is reached?
    By TBrun in forum Excel Formulas & Functions
    Replies: 6
    Last Post: 03-28-2013, 10:37 AM
  3. [SOLVED] Character Count Until a Number is Reached
    By HangMan in forum Excel Formulas & Functions
    Replies: 4
    Last Post: 12-07-2012, 09:48 AM
  4. Delete duplicates after count reached?
    By mpkavanagh in forum Excel Programming / VBA / Macros
    Replies: 6
    Last Post: 02-22-2011, 08:01 PM
  5. Count until certain percentage reached
    By kirby3820 in forum Excel General
    Replies: 2
    Last Post: 02-22-2011, 01:28 PM

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