How to Open Word file (already having Mailmerged details) from excel

gssachin

Board Regular
Joined
Nov 14, 2013
Messages
155
hi,

I Created one master data in excel which I already link to word file through mailmerged. Now I want to Open that document through excel macro. I created following but it's not working as I required (it open only 1 merged record, I want all records should shown in file when I run macro to open that file) .

Sub marco1()
Dim app As Object
Set app = CreateObject("Word.Application")
app.Documents.Open ("\\Sachin\c\CERTIFICATE\Loan from Bank.doc")
app.Application.DisplayAlerts = None
Visible = True


End Sub

Thanks in advanced.
 
If the document you're opening is the mailmerge main document, rather than a file produced by a mailmerge, you don't even have one record - all you have is a mailmerge preview that has been disconnected from the data source. A mailmerge must be executed before a document with all records can come into existence. As it is, if your document is the mailmerge main document, you'd normally be getting an SQL prompt when you open it. Until that is answered, the merge can't execute. However, using Application.DisplayAlerts = False (not None) both prevents the SQL prompt and causes Word to disconnect it from the data source. Consequently, you need to both add the code to turn your document back into a mailmerge main document, supply the SQL string, then execute the merge. Try something along the lines of the following. As you'll see, it's a whole lot more involved than what you have.
Code:
Sub DoMailMerge()
'Note: A VBA Reference to the Word Object Model is required, via Tools|References
Dim wdApp As New Word.Application, wdDoc As Word.Document
Dim strWorkbookName As String: strWorkbookName = ThisWorkbook.FullName
With wdApp
  'Disable alerts to prevent an SQL prompt
  .DisplayAlerts = wdAlertsNone
  'Open the mailmerge main document
  Set wdDoc = .Documents.Open("\\Sachin\c\CERTIFICATE\Loan from Bank.doc", _
    ConfirmConversions:=False, ReadOnly:=True, AddToRecentfiles:=False)
  With wdDoc
    With .MailMerge
      'Define the mailmerge type
      .MainDocumentType = wdFormLetters
      'Define the output
      .Destination = wdSendToNewDocument
      .SuppressBlankLines = True
      'Connect to the data source
      .OpenDataSource Name:=strWorkbookName, ReadOnly:=True, _
        LinkToSource:=False, AddToRecentfiles:=False, _
        Format:=wdOpenFormatAuto, _
        Connection:="Provider=Microsoft.ACE.OLEDB.12.0;" & _
        "User ID=Admin;Data Source=strWorkbookName;" & _
        "Mode=Read;Extended Properties=""HDR=YES;IMEX=1"";", _
        SQLStatement:="SELECT * FROM `Sheet1$`", _
        SubType:=wdMergeSubTypeAccess
      With .DataSource
        .FirstRecord = wdDefaultFirstRecord
        .LastRecord = wdDefaultLastRecord
      End With
      'Excecute the merge
      .Execute
      'Disconnect from the data source
      .MainDocumentType = wdNotAMergeDocument
    End With
    'Close the mailmerge main document
    .Close False
  End With
  'Restore the Word alerts
  .DisplayAlerts = wdAlertsAll
  'Display Word and the document
  .Visible = True
End With
End Sub

Dear sir I'm unable to get past the error 91 "Object variable or With block variable not set". How do I circumvent that?
 
Upvote 0

Excel Facts

Create a Pivot Table on a Map
If your data has zip codes, postal codes, or city names, select the data and use Insert, 3D Map. (Found to right of chart icons).
Fairly obviously, I would have thought, you need to change "\\Sachin\c\CERTIFICATE\Loan from Bank.doc" to match your own situation. You may also need to change the sheet name (i.e. 'Sheet1') in "SELECT * FROM `Sheet1$`".
 
Upvote 0
Fairly obviously, I would have thought, you need to change "\\Sachin\c\CERTIFICATE\Loan from Bank.doc" to match your own situation. You may also need to change the sheet name (i.e. 'Sheet1') in "SELECT * FROM `Sheet1$`".

Dear Paul, yes indeed I did that.....even before I posted it. It just wouldn't work. It's very weird. This is what I got below, with the error code still persistent:

BTW for the context of which I need to achieve:
1) The Word file is contained in a sub-folder of where the Excel file's is, hence I used 'ThisWorkbook.path'
2) I pointed the SQL statement to a Worksheet in the Excel file called 'Guest Speakers'
3) I need to also allow it to filter for a column name called 'Status', where it should = 'Signed'

But the error still persists

Code:
Sub DoMailMerge()
'Note: A VBA Reference to the Word Object Model is required, via Tools|References
Dim wdApp As New Word.Application, wdDoc As Word.Document
Dim strWorkbookName As String: strWorkbookName = ThisWorkbook.FullName
With wdApp
  'Disable alerts to prevent an SQL prompt
  .DisplayAlerts = wdAlertsNone
  'Open the mailmerge main document
  Set wdDoc = .Documents.Open(ThisWorkbook.Path & "\1.2 - Guest Speaker\01 - Approved Guest Speaker Notification.docx", _
    ConfirmConversions:=False, ReadOnly:=True, AddToRecentfiles:=False)
  With wdDoc
    With .MailMerge
      'Define the mailmerge type
      .MainDocumentType = wdFormLetters
      'Define the output
      .Destination = wdSendToNewDocument
      .SuppressBlankLines = True
      'Connect to the data source
      .OpenDataSource Name:=strWorkbookName, ReadOnly:=True, _
        LinkToSource:=False, AddToRecentfiles:=False, _
        Format:=wdOpenFormatAuto, _
        Connection:="Provider=Microsoft.ACE.OLEDB.12.0;" & _
        "User ID=Admin;Data Source=strWorkbookName;" & _
        "Mode=Read;Extended Properties=""HDR=YES;IMEX=1"";", _
        SQLStatement:="SELECT * FROM `Guest Speakers$` WHERE `Status` = `Signed`", _
        SubType:=wdMergeSubTypeAccess
      With .DataSource
        .FirstRecord = wdDefaultFirstRecord
        .LastRecord = wdDefaultLastRecord
      End With
      'Excecute the merge
      .Execute
      'Disconnect from the data source
      .MainDocumentType = wdNotAMergeDocument
    End With
    'Close the mailmerge main document
    .Close False
  End With
  'Restore the Word alerts
  .DisplayAlerts = wdAlertsAll
  'Display Word and the document
  .Visible = True
End With
End Sub
 
Last edited:
Upvote 0
In Word, connect the document to the datasource so it becomes a true mailmerge mail document, then apply the required filter. Having done that, run the following macro and check the output against your code:
Code:
Sub Test()
With ActiveDocument.MailMerge
  If .MainDocumentType <> wdNotAMergeDocument Then
    MsgBox "Mail Merge Data Source Name:" & vbCr & .DataSource.Name
    MsgBox "Mail Merge Connect String:" & vbCr & .DataSource.ConnectString
    MsgBox "Mail Merge Query String:" & vbCr & .DataSource.QueryString
  Else
    MsgBox "Not A Merge Document"
  End If
End With
End Sub
 
Upvote 0
In Word, connect the document to the datasource so it becomes a true mailmerge mail document, then apply the required filter. Having done that, run the following macro and check the output against your code:
Code:
Sub Test()
With ActiveDocument.MailMerge
  If .MainDocumentType <> wdNotAMergeDocument Then
    MsgBox "Mail Merge Data Source Name:" & vbCr & .DataSource.Name
    MsgBox "Mail Merge Connect String:" & vbCr & .DataSource.ConnectString
    MsgBox "Mail Merge Query String:" & vbCr & .DataSource.QueryString
  Else
    MsgBox "Not A Merge Document"
  End If
End With
End Sub

Thanks Paul. Having checked that I have a few findings:
1) A bunch of the Jet OLEDB is missing. I guess it's intentional?
2) I got the wrong SQL filter. But it seems to not affect anything. Changed it and the error persists
3) The only thing that's possible is that the Excel file is on a business OneDrive folder. When I use the Immediate in VBA using '?ThisWorkBook.fullname', this is the output:
Code:
?ThisWorkbook.FullName
https://uedhk.sharepoint.com/sites/sec-resources/Shared Documents/01 - General Office/SEC Departmental OSP.xlsm

But instead, from your shared 'Test' macro, it returns the Local drive (D:\One Drive\The Education University of Hong Kong\EdUHK SEC Department - Documents\01 - General Office\SEC Departmental OSP.xlsm)



When I press debug, the VBA engine points to the With .MailMerge section. It's probably due to something I did, and probably nothing about the properties of the .mailmerge submembers
 
Last edited:
Upvote 0
AFAIK, mailmerge doesn't work with data files in sharepoint folders.

But the file is synced locally

Also, just to make sure I didn't make that statement out of no where, I also tried to do it locally. I copied the entire OneDrive synced file into Drive D, and tried again:

This time something weird happened. The error didn't come up BUT I'm stuck at this weird 'Select Table' prompt. I think it's coz I did something wrong in the SQL statement but I can't figure out why
Code:
Sub DoMailMerge()
'Note: A VBA Reference to the Word Object Model is required, via Tools|References
Dim wdApp As New Word.Application, wdDoc As Word.Document
Dim strWorkbookName As String: strWorkbookName = ThisWorkbook.FullName
With wdApp
  'Disable alerts to prevent an SQL prompt
  .DisplayAlerts = wdAlertsNone
  'Open the mailmerge main document
  Set wdDoc = .Documents.Open(ThisWorkbook.Path & "\1.2 - Guest Speaker\01 - Approved Guest Speaker Notification.docx", _
    ConfirmConversions:=False, ReadOnly:=True, AddToRecentfiles:=False)
  With wdDoc
    With .MailMerge
      'Define the mailmerge type
      .MainDocumentType = wdFormLetters
      'Define the output
      .Destination = wdSendToNewDocument
      .SuppressBlankLines = True
      'Connect to the data source
      .OpenDataSource _
        Name:=strWorkbookName, _
        ReadOnly:=False, _
        LinkToSource:=True, _
        AddToRecentfiles:=False, _
        Format:=wdOpenFormatAuto, _
        Connection:="Provider=Microsoft.ACE.OLEDB.12.0;" & _
        "User ID=Admin;Data Source=strWorkbookName;" & _
        "Mode=Read;Extended Properties=""HDR=YES;IMEX=1"";", _
        SQLStatement:="SELECT * FROM `'Guest_Speakers$'` WHERE `Status` = `Approved`", _
        SubType:=wdMergeSubTypeAccess
      With .DataSource
        .FirstRecord = wdDefaultFirstRecord
        .LastRecord = wdDefaultLastRecord
      End With
      'Excecute the merge
      .Execute
      'Disconnect from the data source
      .MainDocumentType = wdNotAMergeDocument
    End With
    'Close the mailmerge main document
    .Close False
  End With
  'Restore the Word alerts
  .DisplayAlerts = wdAlertsAll
  'Display Word and the document
  .Visible = True
End With
End Sub

Also, I found your response to another user regarding sharepoint: https://www.mrexcel.com/forum/gener...arepoint.html?highlight=sharepoint+mail+merge

I guess it is doable, ultimately?
 
Last edited:
Upvote 0
The string:
`'Guest_Speakers$'`
should probably be:
`Guest_Speakers$`

I checked and verified and I think it's not this part that rendered the error. I tested with the code like below now:

Code:
Sub DoMailMerge()
'Note: A VBA Reference to the Word Object Model is required, via Tools|References
Dim wdApp As New Word.Application, wdDoc As Word.Document, wsName As String
Dim strWorkbookName As String: strWorkbookName = ThisWorkbook.FullName

wsName = ActiveWorkbook.Sheets("Guest Speakers").Name

With wdApp
  'Disable alerts to prevent an SQL prompt
  .DisplayAlerts = wdAlertsNone
  'Open the mailmerge main document
  Set wdDoc = .Documents.Open(ThisWorkbook.Path & "\1.2 - Guest Speaker\01 - Approved Guest Speaker Notification.docx", _
    ConfirmConversions:=True, ReadOnly:=False, AddToRecentfiles:=False)
  With wdDoc
    With .MailMerge
      'Define the mailmerge type
      .MainDocumentType = wdFormLetters
      'Define the output
      .SuppressBlankLines = True
      'Connect to the data source
      .OpenDataSource Name:=strWorkbookName, ReadOnly:=False, _
        LinkToSource:=True, AddToRecentfiles:=False, _
        Format:=wdOpenFormatAuto, _
        Connection:="Provider=Microsoft.ACE.OLEDB.12.0;" & _
        "User ID=Admin;Data Source=strWorkbookName;" & _
        "Mode=Read;Extended Properties=""HDR=YES;IMEX=1"";", _
        SQLStatement:="SELECT * FROM`" & wsName & "$`" '-------- & "WHERE `Status` = Approved", _
        SubType:=wdMergeSubTypeAccess
      With .DataSource
        .FirstRecord = wdDefaultFirstRecord
        .LastRecord = wdDefaultLastRecord
      End With
      'Excecute the merge
      .Execute
      'Disconnect from the data source
      .MainDocumentType = wdNotAMergeDocument
    End With
    'Close the mailmerge main document
    .Close False
  End With
  'Restore the Word alerts
  .DisplayAlerts = wdAlertsAll
  'Display Word and the document
  .Visible = True
End With
End Sub


I specifically quoted out the 'WHERE' condition and it worked fine! (Locally......not on Sharepoint). However when I reapplied the WHERE section it doesn't work again. I believe the ` symbol is placed wrongly there

Also, it is weird that the produced document is a long chain of forms that are all the results of my mail merged documents.....I thought it was supposed to be like a) open the already preset document; b) find where the Excel file destination is and establish connection; c) apply the SQL conditions; d) I can use the 'Mailings' ribbon to navigate the letters one by one (coz I need to email them out)
 
Upvote 0

Forum statistics

Threads
1,223,911
Messages
6,175,333
Members
452,636
Latest member
laura12345

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