+ Reply to Thread
Results 1 to 8 of 8

Counting past occurrence given a classification

  1. #1
    Registered User
    Join Date
    06-06-2014
    Posts
    3

    Counting past occurrence given a classification

    Hello! I have a Table just like the one above. I want to count the number of cells in the column Leg since the last entry, given a certain classification on the column Type.
    For example, for the type KFT only, how many blank entries are there in the column Legendary since the last entry for Leg?

    I know how to solve this issue creating helper columns. But given that I have too many types, I would have to create a helper column for each type, making my table too big given the amount of rows I have. Is there any way I can create a VBA function to perform this task for me, such that I only need one cell per type to let me know the amount of blank cells since last Leg entry for each type? Here is a short example of how my table looks, using only 2 types:

    # Type Com Rar Ep Leg
    1 MSG 4 1
    2 UNG 3 2 1
    3 UNG 4 1
    4 MSG 3 1 1
    5 UNG 4 1
    6 UNG 4 1
    7 MSG 3 1 1



    In this example, I need a formula with output 0 for MSG, since it has been 0 entries since the last Leg for MSG, and output 2 for UNG, since it has been 2 entries since the last Leg for UNG


    Thanks so much for the help!

  2. #2
    Forum Moderator Glenn Kennedy's Avatar
    Join Date
    07-08-2012
    Location
    Digital Nomad... occasionally based in Ireland.
    MS-Off Ver
    O365 (PC) V 2403
    Posts
    44,036

    Re: Counting past occurrence given a classification

    I can't see what's where.

    Will you please attach a SMALL sample Excel workbook (10-20 rows of data is usually enough)? Please don't attach a picture of one (no-one will want to re-type all your stuff before starting).

    1. Make sure that your sample data are truly REPRESENTATIVE of your real data. The use of unrepresentative data is very frustrating and can lead to long delays in reaching a solution.

    2. Make sure that your desired solution is also shown (mock up the results manually).

    3. Make sure that all confidential information is removed first!!

    4. Try to avoid using merged cells. They cause lots of problems!

    Unfortunately the attachment icon doesn't work at the moment. So, to attach an Excel file you have to do the following: Just before posting, scroll down to Go Advanced and then scroll down to Manage Attachments. Now follow the instructions at the top of that screen.
    Glenn




    None of us get paid for helping you... we do this for fun. So DON'T FORGET to say "Thank You" to all who have freely given some of their time to help YOU.

    Temporary addition of accented to illustrate ongoing problem to the TT: L? fh?ile P?draig sona dhaoibh

  3. #3
    Registered User
    Join Date
    06-06-2014
    Posts
    3

    Re: Counting past occurrence given a classification

    Hello Glenn,

    Thanks for the tips. You will find my workbook attached to this post.
    Attached Files Attached Files

  4. #4
    Forum Moderator
    Join Date
    01-21-2014
    Location
    St. Joseph, Illinois U.S.A.
    MS-Off Ver
    Office 365 v 2403
    Posts
    13,406

    Re: Counting past occurrence given a classification

    Try array entering this formula and filling down. If you aren’t familiar with array-entered formulas array enter means the formula must be committed from edit mode by simultaneously pressing and holding down Ctrl and Shift while hitting Enter.
    Formula: copy to clipboard
    Please Login or Register  to view this content.
    Dave

  5. #5
    Forum Guru
    Join Date
    02-27-2016
    Location
    Vietnam
    MS-Off Ver
    2016
    Posts
    5,908

    Re: Counting past occurrence given a classification

    Use helper column:

    In cell L2:

    =IF(B2<>B3,IFERROR(ROW(B2)-LOOKUP(2,1/($B$2:B2=B2)/($F$2:F2<>""),ROW($F$2:F2)),0),"")

  6. #6
    Forum Moderator Glenn Kennedy's Avatar
    Join Date
    07-08-2012
    Location
    Digital Nomad... occasionally based in Ireland.
    MS-Off Ver
    O365 (PC) V 2403
    Posts
    44,036

    Re: Counting past occurrence given a classification

    Is this it????


    =SUMPRODUCT((INDEX(Data!$B$2:$B$190,LARGE(IF(Data!$B$2:$B$190=A3,IF(Data!$F$2:$F$190>0,ROW(Data!$F$2:$F$190))),1)):Data!$B$190=A3)*ISBLANK((INDEX(Data!$F$2:$F$190,LARGE(IF(Data!$B$2:$B$190=A3,IF(Data!$F$2:$F$190>0,ROW(Data!$F$2:$F$190))),1)):Data!$F$190)))

    This is an array formula.

    Array Formulae are a little different from ordinary formulae in that they MUST be confirmed in the FIRST CELL ONLY by pressing CTRL+SHIFT+ENTER to activate the array, not just ENTER. After that, the array can be dragged down as normal, to cover the desired range.

    You will know the array is active when you see curly brackets { } - or "curly braces" for those of you in the USA, or "flower brackets" for those of you in India - appear around the outside of your formula. If you do not use CTRL+SHIFT+ENTER you will (almost always) get an error message or an incorrect answer. Press F2 on that cell and try again.

    Don't type the curly brackets yourself - it won't work...
    Attached Files Attached Files

  7. #7
    Forum Moderator
    Join Date
    01-21-2014
    Location
    St. Joseph, Illinois U.S.A.
    MS-Off Ver
    Office 365 v 2403
    Posts
    13,406

    Re: Counting past occurrence given a classification

    @ makae90

    This is non array entered and simpler than my formula post #4. It returns the same.
    Formula: copy to clipboard
    Please Login or Register  to view this content.


    Also I am apparently interpreting the problem differently than others.

    For example, for the type KFT only, how many blank entries are there in the column Legendary since the last entry for Leg?
    I've interpreted this as the blanks between the last and next to last entry for Leg (that are KFT).

    What am I missing?

    Edit Never mind. What I am missing is the ability to understand plain English.
    In this example, I need a formula with output 0 for MSG, since it has been 0 entries since the last Leg for MSG, and output 2 for UNG, since it has been 2 entries since the last Leg for UNG
    Last edited by FlameRetired; 09-29-2017 at 01:34 PM.

  8. #8
    Forum Moderator Glenn Kennedy's Avatar
    Join Date
    07-08-2012
    Location
    Digital Nomad... occasionally based in Ireland.
    MS-Off Ver
    O365 (PC) V 2403
    Posts
    44,036

    Re: Counting past occurrence given a classification

    Quote Originally Posted by FlameRetired View Post

    What am I missing?

    Edit Never mind. What I am missing is the ability to understand plain English.
    We all do it, from timt to time. RoFLAO

+ 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] Counting occurrence of a value, based on a cell having a value
    By tweaver in forum Excel Formulas & Functions
    Replies: 11
    Last Post: 06-17-2016, 07:25 AM
  2. IF Statement / Occurrence counting
    By DHarper in forum Excel Formulas & Functions
    Replies: 3
    Last Post: 05-29-2013, 10:49 AM
  3. counting the occurrence of a set of continguous values
    By 2013April in forum Excel Programming / VBA / Macros
    Replies: 4
    Last Post: 04-12-2013, 06:09 PM
  4. Counting the occurrence of 2 Criteria on a row in a workbook
    By Chris_Excel_Amateur in forum Excel Formulas & Functions
    Replies: 8
    Last Post: 11-21-2012, 06:13 PM
  5. [SOLVED] Formula for counting occurrence of dates
    By BlueScoob60 in forum Excel Charting & Pivots
    Replies: 4
    Last Post: 08-08-2012, 07:35 AM
  6. Excel 2007 : Counting Occurrence of value across workbooks
    By jonwickert in forum Excel General
    Replies: 0
    Last Post: 05-03-2012, 10:47 AM
  7. Replies: 4
    Last Post: 09-24-2009, 09:57 AM

Tags for this Thread

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