+ Reply to Thread
Results 1 to 7 of 7

Countif to find 2nd occurence in range

  1. #1
    Registered User
    Join Date
    01-13-2010
    Location
    Bakersfield, CA
    MS-Off Ver
    Excel 2003
    Posts
    37

    Countif to find 2nd occurence in range

    I have a range that includes entries with 2 A's, 2 B's, 2 C's etc.
    I want to create a duplicate range with the 1st A as A-1, the 2nd A as A-2 and 1st B as B-1, the 2nd B as B-2, etc. (the attached file shows these in cells)

    I have tried
    =IF(B1="","",B1&"-"&COUNTIF($B$1:$B1,B1))
    but the results are inconsistent, see 3rd range values in red

    The attached file has 3 ranges, from top to bottom:
    1) starting data
    2) how I want the results to look
    3) my approach with ....countif mentioned above.

    Can someone show me how to modify the eqn to give me correct results in all the cells?
    thx
    Attached Files Attached Files
    Last edited by BHudPE; 02-02-2011 at 06:53 PM. Reason: solved

  2. #2
    Forum Expert NBVC's Avatar
    Join Date
    12-06-2006
    Location
    Mississauga, CANADA
    MS-Off Ver
    2003:2010
    Posts
    34,898

    Re: Countif to find 2nd occurence in range

    Try:

    =IF(B2="","",B2&"-"&COUNTIF($B$2:$G2,B2))
    Where there is a will there are many ways.

    If you are happy with the results, please add to the contributor's reputation by clicking the reputation icon (star icon) below left corner

    Please also mark the thread as Solved once it is solved. Check the FAQ's to see how.

  3. #3
    Forum Expert daddylonglegs's Avatar
    Join Date
    01-14-2006
    Location
    England
    MS-Off Ver
    2016
    Posts
    14,675

    Re: Countif to find 2nd occurence in range

    Try this formula in B29 copied across and down

    =IF(B2="","",B2&"-"&COUNTIF($B1:G$1,B2)+COUNTIF($B2:B2,B2))

    [which would accommodate 2 of a letter on a single row - is that possible?]
    Last edited by daddylonglegs; 01-31-2011 at 02:31 PM.
    Audere est facere

  4. #4
    Forum Guru MarvinP's Avatar
    Join Date
    07-23-2010
    Location
    Woodinville, WA
    MS-Off Ver
    Office 365
    Posts
    16,169

    Re: Countif to find 2nd occurence in range

    Hi BHudPE,

    Put this formula in B29, Pull down and across
    Please Login or Register  to view this content.
    I think this is what you want.

    Let us know which one of the 3 formulas worked.
    Attached Files Attached Files
    Last edited by MarvinP; 01-31-2011 at 02:46 PM.
    One test is worth a thousand opinions.
    Click the * Add Reputation below to say thanks.

  5. #5
    Registered User
    Join Date
    01-13-2010
    Location
    Bakersfield, CA
    MS-Off Ver
    Excel 2003
    Posts
    37

    Re: Countif to find 2nd occurence in range

    All three worked, thx for the help. In answering your Q daddylonglegs, no the same letter will not be placed in the same row. But I will study your eqn until I get it, because future uses may fit.

    On the attached file, I added ranges for all 3 eqns I rec'd, so I can inspect them to learn how they work.

    I can't figure out something on the 2nd eqn (daddylonglegs). When seeing your eqn copied dn&over the "$" (from F4) doesn't seem to protected the correct Row &/or Col from changing. See the Blue cells for what I think it should be. Even tho the eqn copied dn&over funny, it works. I'm glad it works, but I don't understand why the cell refs aren't what I would have expected. Do you understand my question daddylonglegs?
    Attached Files Attached Files

  6. #6
    Forum Expert daddylonglegs's Avatar
    Join Date
    01-14-2006
    Location
    England
    MS-Off Ver
    2016
    Posts
    14,675

    Re: Countif to find 2nd occurence in range

    Yep, I messed up the references - what I meant to post was

    =IF(B2="","",B2&"-"&COUNTIF($B1:$G1,B2)+COUNTIF($B2:B2,B2))

    The idea is that the first COUNTIF counts all the instances of B2 in the rows above and the second COUNTIF counts all the instances on that row but only in the cells to the left, I think you'd need that approach if letters were repeated in a row but if you don't then the other approaches suggested by Marvin and NBVC will be better.....

    As it turns out my incorrect $ gives you an invalid range when copied down (you can't have B2:G1 for example) so Excel appears to correct it, and although you get cells referenced to the right, e.g. in columns H and beyond, which I didn't intend, it still works to get the right result because there didn't happen to be anything in those columns.....

  7. #7
    Registered User
    Join Date
    01-13-2010
    Location
    Bakersfield, CA
    MS-Off Ver
    Excel 2003
    Posts
    37

    Re: Countif to find 2nd occurence in range

    thx for clearing that up for me.

+ Reply to Thread

Thread Information

Users Browsing this Thread

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

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