Hi,
If I understand well, you want your data from sheet2 to be added to existing data in sheet1.
That would not be possible with formulas. Formula gar=thers information from "surrounding world" and presents it (somehow processed) in the cell where is written in.
but it can be easily done with a macro.
I had some spare time, so prepared a but more fancy one (although still rather on easy side):
Sub test()
Const DeleteAfterUse = True
Dim i As Long, LastColumn As Range, DestinationColumn As Range, ErrMsg As String
Application.ScreenUpdating = False
With Sheets("Sheet1")
Set LastColumn = .Range("A1").End(xlToRight)
For i = 1 To Cells(Rows.Count, "B").End(xlUp).Row
If IsDate(Cells(i, "B")) Then
Set DestinationColumn = Range(.Range("A1"), LastColumn).Find(what:=Trim(Cells(i, "A")), _
lookat:=xlWhole)
If DestinationColumn Is Nothing Then
ErrMsg = ErrMsg & "Not found" & Cells(i, "A") & " from row: " & i & vbNewLine
Else
.Cells(.Rows.Count, DestinationColumn.Column).End(xlUp).Offset(1, 0) = Cells(i, "B")
If DeleteAfterUse Then Cells(i, "A").Resize(1, 2).ClearContents
End If
Else
ErrMsg = ErrMsg & "non-date value: " & IIf(Len(Cells(i, "B")) > 20, Left(Cells(i, "B"), 17) _
& "...", Cells(i, "B")) & " in row: " & i & vbNewLine
End If
Next i
End With
If Len(ErrMsg) > 0 Then MsgBox ErrMsg, vbCritical, "..:: Errors List! ::.."
Application.ScreenUpdating = True
End Sub
see how it works in the attachment.
some comments
- I think that after succesfull writing into main sheet data shall be deleted from suplementary one. If not, change DeleteAfterUse to False
- Lines with errors (either wrong headings or not-excel-dates will remain not deleted for correction.
- Much larger sheets (but with the same general layout) shall work well. Key points are:
- headers in main sheet starting at A1
- names and dates in supplementary sheet in columns A and B starting from row 1
- Dates are real excel dates: "January 1st, 2014" won't do
- Headers in main sheet are "neat" - now Skill G is written as "Skill G " (with space at the end) - and this will cause errors (in supplementary sheet it is OK)
Bookmarks