• List Unique Names in A Column (Excel 2000)

    Home » Forums » AskWoody support » Productivity software by function » MS Excel and spreadsheet help » List Unique Names in A Column (Excel 2000)

    • This topic has 2 replies, 2 voices, and was last updated 22 years ago.
    Author
    Topic
    #388199

    Is there anyway to list, automatically, the unique Strings in a second column ? In other words, if A1:A10 contains a,b,c,d,d,d,e,e,f,f,, is there a way to list in B1:B6 a,b,c,d,e,f ? I understand you can use filter, but filter does not provide automatic calculation. Is a a dynamic way to do the above without filter or VBA, just using formulas ?

    Viewing 0 reply threads
    Author
    Replies
    • #680508

      Enter this ARRAY formula into (eg) B1:
      =INDEX(A1:A10,SMALL(IF((ROW(INDIRECT(“1:10”))=MATCH(A1:A10,A1:A10,0)),ROW(INDIRECT(“1:10″)),””),ROW(INDIRECT(“1:10”))))

      Select B1:b10, hit F2, ctrl-shift-enter will then fill in B1:b10 with the unique list (where they do not fill in you will get #Num error).

      The list is live. If you change A1:a10 you must also change the “1:10” to reflect the number of rows in the set.

      If you name A1:A10 to LIST you can use the array:
      =INDEX(List,SMALL(IF((ROW(INDIRECT(“1:”&ROWS(List)))=MATCH(List,List,0)),ROW(INDIRECT(“1:”&ROWS(List))),””),ROW(INDIRECT(“1:”&ROWS(List)))))

      And this will keep track of the number of rows required. You still must expand the length of the array to cover all the unique items.

      Steve

    Viewing 0 reply threads
    Reply To: Reply #680508 in List Unique Names in A Column (Excel 2000)

    You can use BBCodes to format your content.
    Your account can't use all available BBCodes, they will be stripped before saving.

    Your information:




    Cancel