You are welcome Dave!
Ι agree with Paul about CopyFromRecordset. It will make updates in a compact area with x rows and y columns, without gap rows as you want.
I thing that the function bellow is very close to what you asking for.
Code:
Function UpdateExcel(ByVal strSQL As String, _
ByVal strTargetWB As String, _
ByVal strTargetCell As String) As Boolean
Dim XL As Excel.Application
Dim WB As Excel.Workbook
Dim rs As DAO.Recordset
Dim Fld As DAO.Field
Dim fWasOpen As Boolean
If Len(Dir(strTargetWB)) = 0 Then
MsgBox "File '" & strTargetWB & "' not found!", vbExclamation
Else
On Error Resume Next
Set XL = GetObject(, "Excel.Application")
fWasOpen = Len(XL.Workbooks(Dir(strTargetWB)).Name) > 0
Set WB = GetObject(strTargetWB)
If WB Is Nothing Then
Set XL = New Excel.Application
XL.Visible = True
Set WB = XL.Workbooks.Open(strTargetWB)
End If
If WB Is Nothing Then
MsgBox "Unable to open " & strTargetWB & "!", vbExclamation
Else
Set rs = CurrentDb.OpenRecordset(strSQL, dbOpenForwardOnly)
If rs Is Nothing Then
MsgBox "Unable to open the '" & strSQL & "' expression!", vbExclamation
Else
On Error GoTo ErrHandler
With WB.Sheets(1)
If rs.RecordCount > 0 Then
'~~~to the nitty-gritty~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~
'Headers in first row
With .Cells(1, .Range(strTargetCell).Column).Resize(1, 8)
.Cells = Array("MANUF NO", "SL-NUMBER", "PARTNER", "PRODUCT TYPE", _
"PO-NUMBER", "SHIPPED", "DELIVERY DATE", "ON LINE XL ROW NO")
.EntireColumn.AutoFit
End With
'Update the values of cells of each row starting form "strTargetCell"
With .Range(strTargetCell)
While Not rs.EOF
For Each Fld In rs.Fields
.Offset(rs![xlRow] - 1, Fld.OrdinalPosition) = Fld
Next Fld
rs.MoveNext
Wend
UpdateExcel = rs.EOF 'All rows updated
End With
'~~~Updates done~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~
Else
MsgBox "There is nothing to export!", vbExclamation
End If
End With
End If
End If
End If
ExitHere:
On Error Resume Next
rs.Close
Set rs = Nothing
If fWasOpen Then
WB.Save
Else
WB.Windows(1).Visible = True
WB.Close True
End If
Set WB = Nothing
Set XL = Nothing
Exit Function
ErrHandler:
Select Case Err
'
Case Else
MsgBox "Unexpected error!" & vbCrLf & Err.Description, _
vbExclamation, "Update Excel Error(" & Err & ")"
Err.Clear
Resume ExitHere
End Select
End Function
You can use it in your code like that:
Code:
If UpdateExcel("tblSheet", CurrentProject.Path & "\TargetBook.xlsx", "c15") Then
MsgBox "TargetBook.xlsx is updated!", vbInformation
End If
Hope this helps!