![]() |
Unique Values in a Column
I have a table that has a column of states. I have formula that will give me
a list of all the unique values in that column: =INDEX($A$2:$A$2208,MATCH(0,COUNTIF($B$2:B2,$A$2:$ A$2208),0)) I'd like to do the same with some vba code to create a new worksheet with the values that it creates. Any suggestions? Niq |
Unique Values in a Column
Here is some code that reference the range selected by the user (column, row,
just a few cells,...) and returns a new sheet with the unique items. There is also some code to find the duplicate items... To use this code you need to refence the project to "Microsoft Scripting Runtime" library. Private Sub GetUniqueItems() Dim cell As Range 'Current cell in range to check Dim rngToSearch As Range 'Cells to be searched Dim dic As Scripting.Dictionary 'Dictionary Object Dim dicItem As Variant 'Items within dictionary object Dim wks As Worksheet 'Worksheet to populate with unique items Dim rngPaste As Range 'Cells where unique items are placed 'Create range to be searched Set rngToSearch = Intersect(ActiveSheet.UsedRange, Selection) If rngToSearch Is Nothing Then Set rngToSearch = ActiveCell 'Confirm there is a relevant range selected If Not rngToSearch Is Nothing Then 'Create dictionay object Set dic = New Scripting.Dictionary 'Populate dictionary object with unique items (use key to define unique) For Each cell In rngToSearch 'Traverse selected range If Not dic.Exists(cell.Value) And cell.Value < Empty Then 'Check the key dic.Add cell.Value, cell.Value 'Add the item if unique End If Next If Not dic Is Nothing Then 'Check for dictionary Set wks = Worksheets.Add 'Create worksheet to populate Set rngPaste = wks.Range("A1") 'Create range to populate For Each dicItem In dic.Items 'Loop through dictionary rngPaste.NumberFormat = "@" 'Format cell as text rngPaste.Value = dicItem 'Add items to new sheet Set rngPaste = rngPaste.Offset(1, 0) 'Increment paste range Next dicItem 'Clean up objects Set wks = Nothing Set rngPaste = Nothing Set dic = Nothing End If End If End Sub Private Sub GetDuplicateItems() Dim cell As Range 'Current cell in range to check Dim rngToSearch As Range 'Cells to be searched Dim dic As Scripting.Dictionary 'Dictionary Object Dim dicItem As Variant 'Items within dictionary object Dim wks As Worksheet 'Worksheet to populate with unique items Dim rngPaste As Range 'Cells where unique items are placed Dim aryDuplicates() As String Dim lngCounter As Long 'Create range to be searched Set rngToSearch = Intersect(ActiveSheet.UsedRange, Selection) If rngToSearch Is Nothing Then Set rngToSearch = ActiveCell lngCounter = 0 'Confirm there is a relevant range selected If Not rngToSearch Is Nothing Then 'Create dictionay object Set dic = New Scripting.Dictionary 'Populate dictionary object with unique items (use key to define unique) For Each cell In rngToSearch 'Traverse selected range If Not dic.Exists(cell.Value) And cell.Value < Empty Then 'Check the key dic.Add cell.Value, cell.Value 'Add the item if unique Else ReDim Preserve aryDuplicates(lngCounter) aryDuplicates(lngCounter) = cell lngCounter = lngCounter + 1 End If Next If lngCounter 0 Then 'Check for values Set wks = Worksheets.Add 'Create worksheet to populate Set rngPaste = wks.Range("A1") 'Create range to populate For lngCounter = LBound(aryDuplicates) To UBound(aryDuplicates) 'Loop duplicates rngPaste.NumberFormat = "@" 'Format cell as text rngPaste.Value = aryDuplicates(lngCounter) 'Add items to new sheet Set rngPaste = rngPaste.Offset(1, 0) 'Increment paste range Next lngCounter 'Clean up objects Set wks = Nothing Set rngPaste = Nothing Else MsgBox "There are no duplicate items in the selected cells.", vbInformation, "No Duplicates" End If Set dic = Nothing End If End Sub -- HTH... Jim Thomlinson "Dominique Feteau" wrote: I have a table that has a column of states. I have formula that will give me a list of all the unique values in that column: =INDEX($A$2:$A$2208,MATCH(0,COUNTIF($B$2:B2,$A$2:$ A$2208),0)) I'd like to do the same with some vba code to create a new worksheet with the values that it creates. Any suggestions? Niq |
Unique Values in a Column
The advanced filter will give you a unique list in a new location.
Sub GetUniques() Dim sh As Worksheet Set sh = Worksheets.Add(After:= _ Worksheets(Worksheets.Count)) Worksheets("Data").Range("A1:A2208") _ .AdvancedFilter Action:=xlFilterCopy, _ CopyToRange:=sh.Range("F1"), _ Unique:=True sh.Columns(6).Sort Key1:=sh.Range("F1"), _ Header:=xlYes End Sub -- Regards, Tom Ogilvy "Dominique Feteau" wrote in message ... I have a table that has a column of states. I have formula that will give me a list of all the unique values in that column: =INDEX($A$2:$A$2208,MATCH(0,COUNTIF($B$2:B2,$A$2:$ A$2208),0)) I'd like to do the same with some vba code to create a new worksheet with the values that it creates. Any suggestions? Niq |
All times are GMT +1. The time now is 12:57 PM. |
Powered by vBulletin® Copyright ©2000 - 2025, Jelsoft Enterprises Ltd.
ExcelBanter.com