+ Reply to Thread
Results 1 to 3 of 3

Finding Duplicate Values in a Col,

  1. #1
    Registered User
    Join Date
    10-31-2003
    Location
    India
    Posts
    24

    Finding Duplicate Values in a Col,

    I have these values in a col A & B.
    And I applied this formulae in col B to find duplicates.
    It is not deducting the last 3 or 4 digits & showing as duplicates, whereas it is not a duplicate.

    =IF(COUNTIF($S$2:S4489,S4489)>1,"d","u")


    362971881060091707 u
    362971881060091708 d
    362971881060116087 u
    362971884070003809 u
    362972161060074451 u
    362972881060075192 u
    362972881060085841 u
    362973151060096917 u
    362973151070001681 u
    362973151070014216 u
    362973151070014275 d
    362973151070014541 d
    362973151070014683 d
    362973151070030576 u
    362973151070030743 d
    362973151070043480 u

  2. #2
    Forum Contributor
    Join Date
    02-28-2006
    Posts
    690
    Make yourself a little test spreadsheet and put 10 single digit numbers in col A, making sure some are duplicates. Put your formula in Column B, dragging it down a further 9 rows. Does it work perfectly? If it does, some of the numbers in your real list may be text, or may have leading or trailing blanks. This is easily checked with a pivot table - look for two apparently identical numbers counted separately.

  3. #3
    Forum Expert NBVC's Avatar
    Join Date
    12-06-2006
    Location
    Mississauga, CANADA
    MS-Off Ver
    2003:2010
    Posts
    34,898
    Quote Originally Posted by Rajkumar
    I have these values in a col A & B.
    And I applied this formulae in col B to find duplicates.
    It is not deducting the last 3 or 4 digits & showing as duplicates, whereas it is not a duplicate.

    =IF(COUNTIF($S$2:S4489,S4489)>1,"d","u")


    362971881060091707 u
    362971881060091708 d
    362971881060116087 u
    362971884070003809 u
    362972161060074451 u
    362972881060075192 u
    362972881060085841 u
    362973151060096917 u
    362973151070001681 u
    362973151070014216 u
    362973151070014275 d
    362973151070014541 d
    362973151070014683 d
    362973151070030576 u
    362973151070030743 d
    362973151070043480 u
    The Countif Functions is "converting" your entries into real numbers as opposed to text strings...and Excel number precision limit is up to 15 digits so it is using only the first 15 digits to count duplicates...

    Try Sumproduct instead....

    e.g. =IF(SUMPRODUCT(--($S$2:S4489=S4489))>1,"d","u")
    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.

+ 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