Copy data from workbook without opening

Sicumera

New Member
Joined
Nov 7, 2013
Messages
12
Hi All

The concept is that as I send out new versions of the tool, users will be able to import the records they have been working on, and that is confined to the "records" sheet, so ideally they would overwrite the whole "records" sheet from a previous file to the new one, through a prompted macro.

I have this issue where I need to import from a user selected workbook a specific sheet to the workbook the macro is being run from.

The reason is that I would like the code not to open the target file, because if I do, the file in question will automatically start its own macro and that will break the flow.

...

Any advice?
 

Excel Facts

Control Word Wrap
Press Alt+Enter to move to a new row in a cell. Lets you control where the words wrap.
This one shoud work for you. It's not the prettiest, but it works pretty well.


Code:
Sub CopyEntireSheet(Filename As String, SheetName As String, DestSheet As String)
'Requires reference to
    Dim cnStr As String
    Dim rs As ADODB.Recordset
    Dim query As String
    Dim WB As Workbook
    'Dim Filename As String
    'Filename = "C:\...\Filename.xlsm"
    cnStr = "Provider=Microsoft.ACE.OLEDB.12.0;" & _
               "Data Source=" & Filename & ";" & _
               "Extended Properties=""Excel 12.0 Macro;HDR=YES""" ';IMEX=1

    query = "SELECT * FROM [" & SheetName & "$]"
    Set rs = New ADODB.Recordset
    rs.Open query, cnStr, adOpenForwardOnly, adLockReadOnly
    
    Set WB = ThisWorkbook
    WB.Sheets(DestSheet).Cells.Clear
    WB.Sheets(DestSheet).Range("A1").CopyFromRecordset rs
    Dim cell As Range, i As Long
    With WB.Sheets(DestSheet).Range("A1").CurrentRegion
        i = 0
        .Cells(1, i + 1).Value = rs.Fields(i).Name
        .EntireColumn.AutoFit
    End With
        cnStr = "Provider=Microsoft.ACE.OLEDB.12.0;" & _
               "Data Source=" & Filename & ";" & _
               "Extended Properties=""Excel 12.0 Macro;HDR=NO""" ';IMEX=1
    Set rs = New Recordset
    rs.Open query, cnStr, adOpenUnspecified, adLockUnspecified
    WB.Sheets(DestSheet).Range("A2").CopyFromRecordset rs
    With WB.Sheets(DestSheet).Range("A2").CurrentRegion
        For i = 1 To rs.Fields.Count - 1
            .Cells(1, i + 1).Value = rs.Fields(i).Name
        Next i
        .EntireColumn.AutoFit
    End With
    
End Sub
 
Upvote 0
Thanks, I will try this out and see if I understand how it works.

At the moment I solved the problem with this


Code:
Private Sub CommandButton2_Click()Dim prece As String
Dim precewb As Workbook


Dim Prompt As String






Prompt = MsgBox("This will import record data from a previous file overwriting the record of the local Dashboard. Do you want to proceed?", vbYesNo, "Proceed?")
If Prompt = vbNo Then GoTo ErrHandler


 
With Application.FileDialog(msoFileDialogFilePicker)
  
  .AllowMultiSelect = False
  .Show
  Err.Clear
  If .SelectedItems.Count <> 0 Then
    prece = .SelectedItems(1)
  End If
  Err.Clear


End With


With Application
        .ScreenUpdating = False
        .EnableEvents = False
    End With
Set precewb = Workbooks.Open(Filename:=prece, ReadOnly:=True)
'ThisWorkbook.SaveLinkValues = False








precewb.Worksheets("record").UsedRange.Copy
'Selection.Copy


ThisWorkbook.Activate
Sheets("Record").Select


Range("a1").Select
ActiveSheet.Paste
precewb.Close SaveChanges:=False




ErrHandler:
'precewb.Close 'SaveChanges:=False
Exit Sub




backhome


End Sub
This actually opens the WB, but it does not start the macro so in the end the result is what I wanted, even if the process is not exactly elegant.
 
Upvote 0

Forum statistics

Threads
1,213,487
Messages
6,113,943
Members
448,534
Latest member
benefuexx

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