+ Reply to Thread
Results 1 to 9 of 9

Concatenate based on unique column combination.

Hybrid View

  1. #1
    Registered User
    Join Date
    08-02-2010
    Location
    Brisbane, Australia
    MS-Off Ver
    Excel 2003
    Posts
    5

    Concatenate based on unique column combination.

    Hi

    I have minimal experience in writing macros in VBA, but was wondering if someone could please help me.

    I have data extracted out of a finincial system where the long text firld is broken over many lines. Each unique combination in columns A, B, and C should have column D concatenated and the orginial lines deleted. I have 25,000 lines, and will do so each quarter.

    I would really appreciate some help - I have tried to leverage off other solutions in the forum, but my VBA knowledge is so poor, I am unable to get them working.

    Attached is a sample of how the data currently looks is in my post below.

    Thanks!
    Last edited by samford; 08-03-2010 at 12:26 AM.

  2. #2
    Forum Guru (RIP) Marcol's Avatar
    Join Date
    12-23-2009
    Location
    Fife, Scotland
    MS-Off Ver
    Excel '97 & 2003/7
    Posts
    7,216

    Re: Concatenate based on unique column combination.

    Hi samford

    Welcome to the forum

    You would do best to post a sample workbook showing Before and After.

    It should clearly illustrate your problem and not contain any sensitive data.

    Cheers

  3. #3
    Registered User
    Join Date
    08-02-2010
    Location
    Brisbane, Australia
    MS-Off Ver
    Excel 2003
    Posts
    5

    Re: Concatenate based on unique column combination.

    Thanks Marcol

    I have attached an example of the original post.

    Cheers
    Attached Files Attached Files
    Last edited by samford; 08-02-2010 at 11:12 PM.

  4. #4
    Forum Guru DonkeyOte's Avatar
    Join Date
    10-22-2008
    Location
    Northumberland, UK
    MS-Off Ver
    O365
    Posts
    21,531

    Re: Concatenate based on unique column combination.

    Here is some basic code - not clear from the sample if Line Item & Text Identifier also need to be considered or not ?

    (below assumes data sorted by PO number and Text Description per the sample)

    Sub Example()
        Dim wsBefore As Worksheet, wsAfter As Worksheet
        Dim vText As Variant
        Dim lngPO As Long, lngRow As Long, lngLast As Long
        Dim xlCalc As XlCalculation
        On Error GoTo Handler
        With Application
            xlCalc = .Calculation
            .ScreenUpdating = False
            .Calculation = xlCalculationManual
            .EnableEvents = False
        End With
        Set wsBefore = Sheets("Before")
        Set wsAfter = Sheets.Add
        With wsAfter
            .Name = "After_" & Format(Now(), "ddmmyyhhmmss")
            .Range("A1:E1").Value = wsBefore.Range("A1:E1").Value
        End With
        With wsBefore
            For lngRow = 2 To .Cells(.Rows.Count, "A").End(xlUp).Row
                lngPO = CLng(.Cells(lngRow, "A").Value)
                If lngPO > 0 Then
                    If InStr(1, .Cells(lngRow, "D"), "Header Note", vbTextCompare) Then
                        lngLast = lngRow
                    Else
                        lngLast = Application.WorksheetFunction.Match(lngPO, .Columns(1))
                    End If
                    With .Range(.Cells(lngRow, "E"), .Cells(lngLast, "E"))
                        vText = .Parent.Evaluate("TRANSPOSE(IF(ROW(" & .Address & ")," & .Address & "))")
                    End With
                    With wsAfter
                        With .Cells(.Rows.Count, "A").End(xlUp).Offset(1)
                            .Resize(, 4).Value = wsBefore.Cells(lngRow, "A").Resize(, 4).Value
                            .Offset(, 4).Value = Join(vText, " ")
                        End With
                    End With
                    lngRow = lngLast
                End If
            Next lngRow
        End With
        wsAfter.Columns("A:E").AutoFit
    ExitPoint:
        Set wsBefore = Nothing
        Set wsAfter = Nothing
        With Application
            .ScreenUpdating = True
            .Calculation = xlCalc
            .EnableEvents = True
        End With
        On Error GoTo 0
        Exit Sub
    
    Handler:
        MsgBox "Error " & Err.Number & " (" & Err.Description & ")"
        Resume ExitPoint
    End Sub
    Working example attached.
    Attached Files Attached Files

  5. #5
    Registered User
    Join Date
    08-02-2010
    Location
    Brisbane, Australia
    MS-Off Ver
    Excel 2003
    Posts
    5

    Re: Concatenate based on unique column combination.

    Thanks DonkeyOte.

    Sorry to be a pain, but now I get an error: "Error 9 (subscript out of range)"

    Am I missing something?

  6. #6
    Forum Guru DonkeyOte's Avatar
    Join Date
    10-22-2008
    Location
    Northumberland, UK
    MS-Off Ver
    O365
    Posts
    21,531

    Re: Concatenate based on unique column combination.

    Are you referring to the sample file or your own file ?

    Note in the sample file wsBefore is specified as being named "Before" - modify as appropriate.

  7. #7
    Registered User
    Join Date
    08-02-2010
    Location
    Brisbane, Australia
    MS-Off Ver
    Excel 2003
    Posts
    5

    Re: Concatenate based on unique column combination.

    DonkeyOte

    All sorted, an "=" sign had come through in one of the field from the database, so excel was expecting a formula. Once the "=" was deleted, your macro worked like a charm.

    Thanks for taking the time to assist.

+ Reply to Thread

Thread Information

Users Browsing this Thread

There are currently 1 users browsing this thread. (0 members and 1 guests)

Tags for this Thread

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