Concatanate cells in rows, when there are duplicate numbers in column

scorpioasb

New Member
Joined
Jan 15, 2010
Messages
4
:confused:I have searched and searched for an answer to this until my brain is now smoking. My spreadsheet has data in Col A1, and there are duplicate numbers in that column based on the number of visits. Each visit has a date, and has comments, there could be from one to 20 comments for each number in A1, in separate rows. My goal is to merge all of the comments based on the lookup value in column A, even the blanks because I have to count that as a visit. My example is below. What is the best way to do this?? My data range is A2:G2872.


E*1 Visit Date Remarks
11180 1/1/10 Checked location
11180 1/2/10 Plunger
11180 1/3/10 Access blocked
11190 1/6/10 Measured water
11190 1/6/10 Checked tank
21166 12/13/09 Took reading
21166 12/18/09

Thanks you SO MUCH in advance!
 

Excel Facts

Round to nearest half hour?
Use =MROUND(A2,"0:30") to round to nearest half hour. Use =CEILING(A2,"0:30") to round to next half hour.
String concatenation is not a built-in function to Excel. You'll have to add it. Here's a UserDefinedFunction (UDF) from here on the forum I use for this task:

Code:
Option Explicit

Function ConcatIf(ByVal compareRange As Range, ByVal xCriteria As Variant, Optional ByVal stringsRange As Range, _
            Optional Delimiter As String, Optional NoDuplicates As Boolean) As String
    ' code base by Mike Rickson, MrExcel MVP
    ' used as exactly like SUMIF() with two additional parameters
    ' of delimiter and "no duplicates" as TRUE/FALSE if concatenated values
    ' might include duplicates  ex. =ConcatIf($A$1:$A$10, C1, $B$1:$B$10, ",", True)

Dim i As Long, j As Long

With compareRange.Parent
    Set compareRange = Application.Intersect(compareRange, Range(.UsedRange, .Range("a1")))
End With

If compareRange Is Nothing Then Exit Function
If stringsRange Is Nothing Then Set stringsRange = compareRange
Set stringsRange = compareRange.Offset(stringsRange.Row - compareRange.Row, _
                                    stringsRange.Column - compareRange.Column)
    
    For i = 1 To compareRange.Rows.Count
        For j = 1 To compareRange.Columns.Count
            If (Application.CountIf(compareRange.Cells(i, j), xCriteria) = 1) Then
                If InStr(ConcatIf, Delimiter & CStr(stringsRange.Cells(i, j))) <> 0 Imp Not (NoDuplicates) Then
                    ConcatIf = ConcatIf & Delimiter & CStr(stringsRange.Cells(i, j))
                End If
            End If
        Next j
    Next i
    ConcatIf = Mid(ConcatIf, Len(Delimiter) + 1)
End Function

============
How to install the User Defined Function:

1. Open up your workbook
2. Get into VB Editor (Press Alt+F11)
3. Insert a new module (Insert > Module)
4. Copy and Paste in your code (given above)
5. Get out of VBA (Press Alt+Q)
6. Save your sheet

The function is installed and ready to use.
=========

First, highlight your column A, and use DATA > FILTER > ADVANCED FILTER to Copy to another location: H1 > [x] Unique values only

This will create a list in column H of all your column A codes.

Then put the formula shown here into I2, then copy down.

Excel Workbook
ABCDHI
1E*1Visit DateRemarksE*1Remarks
2111801/1/2010Checked location11180Checked location, Plunger , Access blocked
3111801/2/2010Plunger11190Measured water, Checked tank
4111801/3/2010Access blocked21166Took reading,
5111901/6/2010Measured water
6111901/6/2010Checked tank
72116612/13/2009Took reading
82116612/18/2009
Sheet1



The CONCATIF() function you added acts like a SUMIF() with two additional parameters.

Here's a link to a complete explanation:

http://www.excelforum.com/excel-programming/682761-looking-to-prevent-duplicate-text-in-cell.html#6
 
Upvote 0
Maybe this?
If it's like what you want then post back if you want the results presented differently.
Code:
Sub trythis()
Dim n, c(), a, i, v
n = Range("A" & Rows.Count).End(xlUp).Row
ReDim c(1 To n, 1 To 1)
a = Range("A1").Resize(n, 3)
For i = 2 To n
If Not a(i, 1) = a(i - 1, 1) Then
    v = i
    c(v, 1) = a(i, 3)
Else
    c(v, 1) = c(v, 1) & ", " & a(i, 3)
End If
Next i
Range("E1").Resize(n) = c
End Sub
 
Upvote 0
Aha! That is why, because of the coding that I don't use much. I worked until my eyes popped out on this one, and it will come in handy because I deal with a lot of duplicate ID's with different outcomes. I will try this and let you know.

THANK YOU!
 
Upvote 0
Wellllllllll, thanks to you, IT WORKED! Thank you so very, very much. You can't imagine how much easier this will make my life. Here I think I am an Excel power user and I have way too much to learn. I knew there was a way. Thank you again.:ROFLMAO:
 
Upvote 0
I tried yours first and it worked like a charm. Check out the big brain! Thanks again, this will save me oodles of time.
 
Upvote 0

Forum statistics

Threads
1,215,960
Messages
6,127,942
Members
449,411
Latest member
sdescharme

We've detected that you are using an adblocker.

We have a great community of people providing Excel help here, but the hosting costs are enormous. You can help keep this site running by allowing ads on MrExcel.com.
Allow Ads at MrExcel

Which adblocker are you using?

Disable AdBlock

Follow these easy steps to disable AdBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the icon in the browser’s toolbar.
2)Click on the "Pause on this site" option.
Go back

Disable AdBlock Plus

Follow these easy steps to disable AdBlock Plus

1)Click on the icon in the browser’s toolbar.
2)Click on the toggle to disable it for "mrexcel.com".
Go back

Disable uBlock Origin

Follow these easy steps to disable uBlock Origin

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back

Disable uBlock

Follow these easy steps to disable uBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back
Back
Top