+ Reply to Thread
Results 1 to 3 of 3

Identifying First Instance of a Value Given a Criteria

  1. #1
    carl
    Guest

    Identifying First Instance of a Value Given a Criteria



    My data table is like this:

    Date ID
    20060403 123
    20060403 456
    20060403 789
    20060403 123
    20060403 222
    20060403 222
    20060404 123
    20060404 888
    20060404 777
    20060404 222

    I am using a formula like this in ColC

    =COUNTIF($B$2:B2,B2)=1

    to help ID first instance of a given ID

    It gives a result like this:

    Date ID
    20060403 123 TRUE
    20060403 456 TRUE
    20060403 789 TRUE
    20060403 123 FALSE
    20060403 222 TRUE
    20060403 222 FALSE
    20060404 123 FALSE
    20060404 888 TRUE
    20060404 777 TRUE
    20060404 222 FALSE


    I would like to modify the formula to identify the first instance for each
    day - some of the ID are re-used on a day-to-day basis.

    A result like this is what I am targeting:

    Date ID
    20060403 123 TRUE
    20060403 456 TRUE
    20060403 789 TRUE
    20060403 123 FALSE
    20060403 222 TRUE
    20060403 222 FALSE
    20060404 123 TRUE
    20060404 888 TRUE
    20060404 777 TRUE
    20060404 222 TRUE


    Is this possible ?

    Thank you in advance.




  2. #2
    Bob Phillips
    Guest

    Re: Identifying First Instance of a Value Given a Criteria

    =SUMPRODUCT(--($A$2:A2=A2),--($B$2:B2=B2))=1

    --
    HTH

    Bob Phillips

    (remove nothere from email address if mailing direct)

    "carl" <[email protected]> wrote in message
    news:[email protected]...
    >
    >
    > My data table is like this:
    >
    > Date ID
    > 20060403 123
    > 20060403 456
    > 20060403 789
    > 20060403 123
    > 20060403 222
    > 20060403 222
    > 20060404 123
    > 20060404 888
    > 20060404 777
    > 20060404 222
    >
    > I am using a formula like this in ColC
    >
    > =COUNTIF($B$2:B2,B2)=1
    >
    > to help ID first instance of a given ID
    >
    > It gives a result like this:
    >
    > Date ID
    > 20060403 123 TRUE
    > 20060403 456 TRUE
    > 20060403 789 TRUE
    > 20060403 123 FALSE
    > 20060403 222 TRUE
    > 20060403 222 FALSE
    > 20060404 123 FALSE
    > 20060404 888 TRUE
    > 20060404 777 TRUE
    > 20060404 222 FALSE
    >
    >
    > I would like to modify the formula to identify the first instance for each
    > day - some of the ID are re-used on a day-to-day basis.
    >
    > A result like this is what I am targeting:
    >
    > Date ID
    > 20060403 123 TRUE
    > 20060403 456 TRUE
    > 20060403 789 TRUE
    > 20060403 123 FALSE
    > 20060403 222 TRUE
    > 20060403 222 FALSE
    > 20060404 123 TRUE
    > 20060404 888 TRUE
    > 20060404 777 TRUE
    > 20060404 222 TRUE
    >
    >
    > Is this possible ?
    >
    > Thank you in advance.
    >
    >
    >




  3. #3
    Peo Sjoblom
    Guest

    Re: Identifying First Instance of a Value Given a Criteria

    =SUMPRODUCT(--($A$2:A2&$B$2:B2=A2&B2))=1

    copy down


    --

    Regards,

    Peo Sjoblom

    http://nwexcelsolutions.com



    "carl" <[email protected]> wrote in message
    news:[email protected]...
    >
    >
    > My data table is like this:
    >
    > Date ID
    > 20060403 123
    > 20060403 456
    > 20060403 789
    > 20060403 123
    > 20060403 222
    > 20060403 222
    > 20060404 123
    > 20060404 888
    > 20060404 777
    > 20060404 222
    >
    > I am using a formula like this in ColC
    >
    > =COUNTIF($B$2:B2,B2)=1
    >
    > to help ID first instance of a given ID
    >
    > It gives a result like this:
    >
    > Date ID
    > 20060403 123 TRUE
    > 20060403 456 TRUE
    > 20060403 789 TRUE
    > 20060403 123 FALSE
    > 20060403 222 TRUE
    > 20060403 222 FALSE
    > 20060404 123 FALSE
    > 20060404 888 TRUE
    > 20060404 777 TRUE
    > 20060404 222 FALSE
    >
    >
    > I would like to modify the formula to identify the first instance for each
    > day - some of the ID are re-used on a day-to-day basis.
    >
    > A result like this is what I am targeting:
    >
    > Date ID
    > 20060403 123 TRUE
    > 20060403 456 TRUE
    > 20060403 789 TRUE
    > 20060403 123 FALSE
    > 20060403 222 TRUE
    > 20060403 222 FALSE
    > 20060404 123 TRUE
    > 20060404 888 TRUE
    > 20060404 777 TRUE
    > 20060404 222 TRUE
    >
    >
    > Is this possible ?
    >
    > Thank you in advance.
    >
    >
    >




+ 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