+ Reply to Thread
Results 1 to 10 of 10

Modify to Run On Specific Column and Remove trailing digits in string

Hybrid View

  1. #1
    Registered User
    Join Date
    08-01-2011
    Location
    Rome, Georgia
    MS-Off Ver
    Excel 2007
    Posts
    7

    Modify to Run On Specific Column and Remove trailing digits in string

    I have a sheet that has an identifier like 1325686468.2958 on each line of column H. The digits leading up to the "." are the one's that matter to me. I need to keep 1 entry for each unique identifier. I have a macro that I picked up that deletes the entire row based on duplicates in the selected column which is great but I need it modified to first eliminate the 4 trailing digits. Also, this identifier will always be in column H, can i make it run there everytime instead of having to select that column first? Any help would be greatly appciated.

    Sub RemoveDupes2()
    Dim LR As Long
    Dim COL As Long
    
    COL = ActiveCell.Column
    LR = Cells(Rows.Count, COL).End(xlUp).Row
    
    With Range(Cells(1, Columns.Count), Cells(LR, Columns.Count))
        .FormulaR1C1 = "=IF(COUNTIF(R1C" & COL & ":RC" & COL & ",RC" & COL & ")=COUNTIF(C" & COL & ",RC" & COL & "), 1, """")"
        .SpecialCells(xlCellTypeFormulas, 2).EntireRow.Delete xlShiftUp
        .ClearContents
    End With
    
    End Sub
    Last edited by pmterp; 01-13-2012 at 12:28 AM.

  2. #2
    Valued Forum Contributor
    Join Date
    12-02-2009
    Location
    Austin, Tx
    MS-Off Ver
    Office 365 64-Bit, 2108, build 14326.21018
    Posts
    3,968

    Re: Modify to Run On Specific Column and Remove trailing digits in string

    Try this, see if it does the trick:
    Sub RemoveDupes3()
    Dim LR As Long
    Dim COL As Long
    
    Columns("H").Select 'Change to the pertinent column
    COL = ActiveCell.Column
    LR = Cells(Rows.Count, COL).End(xlUp).Row
    
    'This code will convert your numbers to integers (strip away everything after the decimal)
        For Each ce In Range("H1:H" & LR).SpecialCells(xlCellTypeConstants, 1)
            ce.Value = Int(ce.Value)
        Next ce
    
    'Didn't touch this code
    With Range(Cells(1, Columns.Count), Cells(LR, Columns.Count))
        .FormulaR1C1 = "=IF(COUNTIF(R1C" & COL & ":RC" & COL & ",RC" & COL & ")=COUNTIF(C" & COL & ",RC" & COL & "), 1, """")"
        .SpecialCells(xlCellTypeFormulas, 2).EntireRow.Delete xlShiftUp
        .ClearContents
    End With
    
    End Sub

  3. #3
    Forum Expert JBeaucaire's Avatar
    Join Date
    03-21-2004
    Location
    Bakersfield, CA
    MS-Off Ver
    2010, 2016, Office 365
    Posts
    33,492

    Re: Modify to Run On Specific Column and Remove trailing digits in string

    Try this on a copy of your data:
    Option Explicit
    
    Sub RemoveDupes3()
    Dim LR As Long
    
    LR = Range("H" & Rows.Count).End(xlUp).Row
    
    With Range(Cells(1, Columns.Count), Cells(LR, Columns.Count))
        .FormulaR1C1 = "=INT(RC8)"
        .Copy
        Range("H1").PasteSpecial xlPasteValues
        .FormulaR1C1 = "=IF(COUNTIF(R1C8:RC8, RC8) = COUNTIF(C8, RC8), 1, """")"
        .SpecialCells(xlCellTypeFormulas, 2).EntireRow.Delete xlShiftUp
        .ClearContents
    End With
    
    End Sub
    _________________
    Microsoft MVP 2010 - Excel
    Visit: Jerry Beaucaire's Excel Files & Macros

    If you've been given good help, use the icon below to give reputation feedback, it is appreciated.
    Always put your code between code tags. [CODE] your code here [/CODE]

    ?None of us is as good as all of us? - Ray Kroc
    ?Actually, I *am* a rocket scientist.? - JB (little ones count!)

  4. #4
    Registered User
    Join Date
    08-01-2011
    Location
    Rome, Georgia
    MS-Off Ver
    Excel 2007
    Posts
    7

    Re: Modify to Run On Specific Column and Remove trailing digits in string

    Thank you both so much. Both worked great, however, I ran into another problem I didn't realize was there with this macro. It keeps the last entry of the duplicates (which is what my original macro did). I actually need to keep the top entry of each set of dup's instead. Is there a way to change this?

  5. #5
    Forum Expert JBeaucaire's Avatar
    Join Date
    03-21-2004
    Location
    Bakersfield, CA
    MS-Off Ver
    2010, 2016, Office 365
    Posts
    33,492

    Re: Modify to Run On Specific Column and Remove trailing digits in string

    Like so:
    Option Explicit
    
    Sub RemoveDupes3()
    Dim LR As Long
    
    LR = Range("H" & Rows.Count).End(xlUp).Row
    
    With Range(Cells(1, Columns.Count), Cells(LR, Columns.Count))
        .FormulaR1C1 = "=INT(RC8)"
        .Copy
        Range("H1").PasteSpecial xlPasteValues
        .FormulaR1C1 = "=IF(COUNTIF(R1C8:RC8, RC8) = 1, 1, """")"
        .SpecialCells(xlCellTypeFormulas, 2).EntireRow.Delete xlShiftUp
        .ClearContents
    End With
    
    End Sub

  6. #6
    Registered User
    Join Date
    08-01-2011
    Location
    Rome, Georgia
    MS-Off Ver
    Excel 2007
    Posts
    7

    Re: Modify to Run On Specific Column and Remove trailing digits in string

    Awesome. I've modified it just a little because I changed it so the person pulling the report can choose all fields and first it will delete the unneeded columns based on their headers. This now makes column D where all the action happens. One last challenge I'm facing. When it finishes, row 1, which contains my header is also somehow changed. I tried a few things to make it start in Row 2 but I've not been successful. Help is appreciated.
    Sub RemoveDupes()
    Dim LR As Long
    Dim COL As Long
    
    Dim a As Long
    Application.ScreenUpdating = False
    For a = 25 To 1 Step -1
      Select Case Cells(1, a).Value
        Case "Call flow", "Call type", "Application", "Ringing started", "Call answered", "Call disposition", "Charging plan", "Call cost", "Money unit", "Transfer source", "Transfer destination", "Initially called extension", "Callback CallerID", "Calling card code", "Flow reference extension"
          Cells(1, a).EntireColumn.Delete
      End Select
    Next a
    Application.ScreenUpdating = True
    
    LR = Range("E" & Rows.Count).End(xlUp).Row
    
    With Range(Cells(1, Columns.Count), Cells(LR, Columns.Count))
        .FormulaR1C1 = "=INT(RC5)"
        .Copy
        Range("E1").PasteSpecial xlPasteValues
        .FormulaR1C1 = "=IF(COUNTIF(R1C5:RC5, RC5) = 1, 1, """")"
        .SpecialCells(xlCellTypeFormulas, 2).EntireRow.Delete xlShiftUp
        .ClearContents
    End With
    
    End Sub
    Last edited by pmterp; 01-09-2012 at 10:09 PM. Reason: error in code

  7. #7
    Valued Forum Contributor
    Join Date
    12-02-2009
    Location
    Austin, Tx
    MS-Off Ver
    Office 365 64-Bit, 2108, build 14326.21018
    Posts
    3,968

    Re: Modify to Run On Specific Column and Remove trailing digits in string

    PMTerp,

    I think that all that's needed is to change the range you're looking at. Instead of Row 1, you want to start on Row 2. See the change I made in your code below, let me know if it works.

    Sub RemoveDupes()
    Dim LR As Long
    Dim COL As Long
    
    Dim a As Long
    Application.ScreenUpdating = False
    For a = 25 To 1 Step -1
      Select Case Cells(1, a).Value
        Case "Call flow", "Call type", "Application", "Ringing started", "Call answered", "Call disposition", "Charging plan", "Call cost", "Money unit", "Transfer source", "Transfer destination", "Initially called extension", "Callback CallerID", "Calling card code", "Flow reference extension"
          Cells(1, a).EntireColumn.Delete
      End Select
    Next a
    Application.ScreenUpdating = True
    
    LR = Range("E" & Rows.Count).End(xlUp).Row
    
    With Range(Cells(2, Columns.Count), Cells(LR, Columns.Count))
        .FormulaR1C1 = "=INT(RC5)"
        .Copy
        Range("E2").PasteSpecial xlPasteValues
        .FormulaR1C1 = "=IF(COUNTIF(R1C5:RC5, RC5) = 1, 1, """")"
        .SpecialCells(xlCellTypeFormulas, 2).EntireRow.Delete xlShiftUp
        .ClearContents
    End With
    
    End Sub.

  8. #8
    Forum Expert JBeaucaire's Avatar
    Join Date
    03-21-2004
    Location
    Bakersfield, CA
    MS-Off Ver
    2010, 2016, Office 365
    Posts
    33,492

    Re: Modify to Run On Specific Column and Remove trailing digits in string

    Right here:
    With Range(Cells(2, Columns.Count), Cells(LR, Columns.Count))

  9. #9
    Registered User
    Join Date
    08-01-2011
    Location
    Rome, Georgia
    MS-Off Ver
    Excel 2007
    Posts
    7

    Re: Modify to Run On Specific Column and Remove trailing digits in string

    Thanks JBeaucaire and Jomili That was exactly what I needed. You are Awesome!

  10. #10
    Forum Expert JBeaucaire's Avatar
    Join Date
    03-21-2004
    Location
    Bakersfield, CA
    MS-Off Ver
    2010, 2016, Office 365
    Posts
    33,492

    Re: Modify to Run On Specific Column and Remove trailing digits in string

    If that takes care of your need, please click EDIT in your original post, click GO ADVANCED and set the PREFIX box to SOLVED.

+ 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